127 lines
4.2 KiB
SQL
127 lines
4.2 KiB
SQL
DELIMITER $$
|
|
CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `sage`.`clientSupplier_add`(
|
|
vCompanyFk INT
|
|
)
|
|
BEGIN
|
|
/**
|
|
* Inserta en la tabla sage.clientesProveedores los datos de clientes y proveedores
|
|
* que se actualizaran o se daran de alta en Sage
|
|
* @vCompanyFk Id de empresa
|
|
* @table tmp.clientSupplier(idClientSupplier, `type`)
|
|
*/
|
|
DECLARE vCountryCeutaMelillaFk INT;
|
|
DECLARE vCompanyCode INT DEFAULT company_getCode(vCompanyFk);
|
|
DECLARE vCountryCanariasCode, vCountryCeutaMelillaCode VARCHAR(2);
|
|
|
|
SELECT SiglaNacion INTO vCountryCanariasCode
|
|
FROM Naciones
|
|
WHERE Nacion ='ISLAS CANARIAS';
|
|
|
|
SELECT CodigoNacion, SiglaNacion INTO vCountryCeutaMelillaFk, vCountryCeutaMelillaCode
|
|
FROM Naciones
|
|
WHERE Nacion ='CEUTA Y MELILLA';
|
|
|
|
TRUNCATE TABLE clientesProveedores;
|
|
|
|
INSERT INTO clientesProveedores
|
|
(CodigoEmpresa,
|
|
ClienteOProveedor,
|
|
CodigoClienteProveedor,
|
|
RazonSocial,
|
|
Nombre,
|
|
Domicilio,
|
|
CodigoCuenta,
|
|
CifDni,
|
|
CifEuropeo,
|
|
CodigoPostal,
|
|
Municipio,
|
|
CodigoProvincia,
|
|
Provincia,
|
|
CodigoNacion,
|
|
SiglaNacion,
|
|
PersonaFisicaJuridica,
|
|
TipoDocumentoPersona,
|
|
CodigoIva,
|
|
Nacion,
|
|
Telefono,
|
|
Telefono2,
|
|
CodigoTransaccion,
|
|
CodigoRetencion,
|
|
Email1,
|
|
iban)
|
|
SELECT
|
|
vCompanyCode,
|
|
'C',
|
|
c.id,
|
|
c.socialName,
|
|
c.socialName,
|
|
IFNULL(c.street, ''),
|
|
c.accountingAccount,
|
|
@fi := IF(cu.code = LEFT(TRIM(c.fi), 2) AND c.isVies, MID(TRIM(c.fi), 3, LENGTH(TRIM(c.fi))-1), TRIM(c.fi)),
|
|
IF(c.isVies, CONCAT(IFNULL(cu.viesCode,cu.code), @fi ), TRIM(c.fi)),
|
|
IFNULL(c.postcode, ''),
|
|
IFNULL(c.city, ''),
|
|
IFNULL(pr.CodigoProvincia, ''),
|
|
IFNULL(p.name, ''),
|
|
IF(n.SiglaNacion = vCountryCanariasCode COLLATE utf8mb3_unicode_ci, IF(@isCeutaMelilla := IF(pr.Provincia IN ('CEUTA', 'MELILLA'), TRUE, FALSE), vCountryCeutaMelillaFk, IF (@isCanarias, vCountryCanariasCode, n.CodigoNacion)), n.CodigoNacion),
|
|
IF(n.SiglaNacion = vCountryCanariasCode COLLATE utf8mb3_unicode_ci, IF(@isCeutaMelilla, vCountryCeutaMelillaCode, IF (@isCanarias, vCountryCanariasCode, n.SiglaNacion)), n.SiglaNacion),
|
|
IF((c.fi REGEXP '^([[:blank:]]|[[:digit:]])'), 'J','F'),
|
|
IF(cu.code = 'ES',
|
|
1,
|
|
IF((cu.isUeeMember AND c.isVies), 2, 4)),
|
|
IFNULL(c.taxTypeSageFk,0),
|
|
IF(n.SiglaNacion = vCountryCanariasCode COLLATE utf8mb3_unicode_ci,
|
|
IF(@isCeutaMelilla, 'CEUTA Y MELILLA', IF (@isCanarias, 'ISLAS CANARIAS', n.Nacion)),
|
|
n.Nacion),
|
|
IFNULL(c.phone, ''),
|
|
IFNULL(c.mobile, ''),
|
|
IFNULL(c.transactionTypeSageFk, 0),
|
|
'0',
|
|
IFNULL(SUBSTR(c.email, 1, LOCATE(',', CONCAT(c.email, ','))-1), ''),
|
|
IFNULL(c.iban, '')
|
|
FROM vn.`client` c
|
|
JOIN tmp.clientSupplier cs ON cs.idClientSupplier = c.id
|
|
LEFT JOIN vn.country cu ON cu.id = c.countryFk
|
|
LEFT JOIN Naciones n ON n.countryFk = cu.id
|
|
LEFT JOIN vn.province p ON p.id = c.provinceFk
|
|
LEFT JOIN Provincias pr ON pr.provinceFk = p.id
|
|
WHERE cs.type = 'C'
|
|
UNION ALL
|
|
SELECT vCompanyCode,
|
|
'P',
|
|
s.id,
|
|
s.name,
|
|
s.name,
|
|
IFNULL(s.street, ''),
|
|
s.account,
|
|
@nif := IF(co.code = LEFT(TRIM(s.nif), 2), MID(TRIM(s.nif), 3, LENGTH(TRIM(s.nif))-1), TRIM(s.nif)),
|
|
IF(s.isVies, CONCAT(IFNULL(co.viesCode,co.code), @nif), TRIM(s.nif)),
|
|
IFNULL(s.postCode,''),
|
|
IFNULL(s.city, ''),
|
|
IFNULL(pr.CodigoProvincia, ''),
|
|
IFNULL(p.name, ''),
|
|
n.CodigoNacion,
|
|
n.SiglaNacion COLLATE utf8mb3_unicode_ci,
|
|
IF((s.nif REGEXP '^([[:blank:]]|[[:digit:]])'),'J','F'),
|
|
IF(co.code = 'ES', 1, IF(co.isUeeMember, 2, 4)),
|
|
IFNULL(s.taxTypeSageFk, 0),
|
|
n.Nacion,
|
|
IFNULL(sc.phone, ''),
|
|
IFNULL(sc.mobile, ''),
|
|
IFNULL(s.transactionTypeSageFk, 0),
|
|
IFNULL(s.withholdingSageFk, '0'),
|
|
IFNULL(SUBSTR(sc.email, 1, (COALESCE(NULLIF(LOCATE(',', sc.email), 0), 99) - 1)), ''),
|
|
IFNULL(sa.iban, '')
|
|
FROM vn.supplier s
|
|
JOIN tmp.clientSupplier cs ON cs.idClientSupplier = s.id
|
|
LEFT JOIN vn.country co ON co.id = s.countryFk
|
|
LEFT JOIN Naciones n ON n.countryFk = co.id
|
|
LEFT JOIN vn.province p ON p.id = s.provinceFk
|
|
LEFT JOIN Provincias pr ON pr.provinceFk = p.id
|
|
LEFT JOIN vn.supplierContact sc ON sc.supplierFk = s.id
|
|
LEFT JOIN vn.supplierAccount sa ON sa.supplierFk = s.id
|
|
WHERE cs.type = 'P'
|
|
GROUP BY s.id;
|
|
END$$
|
|
DELIMITER ;
|