125 lines
4.1 KiB
SQL
125 lines
4.1 KiB
SQL
CREATE DEFINER=`root`@`localhost` PROCEDURE `sage`.`clientSupplier_add`(vCompanyFk INT)
|
|
BEGIN
|
|
/**
|
|
* Prepara los datos de clientes y proveedores para exportarlos a Sage
|
|
* @vCompanyFk Empresa dela que se quiere trasladar datos
|
|
*/
|
|
DECLARE vCountryCeutaMelillaFk INT;
|
|
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
|
|
company_getCode(vCompanyFk),
|
|
'C',
|
|
c.id,
|
|
c.socialName,
|
|
c.socialName,
|
|
IFNULL(c.street, ''),
|
|
c.accountingAccount,
|
|
TRIM(IF(cu.code = LEFT(c.fi, 2), MID(c.fi, 3, LENGTH(c.fi)-1), c.fi)),
|
|
IF(n.NacionCEE,TRIM(IF(cu.code = LEFT(c.fi, 2), c.fi, CONCAT(cu.code,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 IN('ES','EX'),
|
|
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 clientLastTwoMonths clm ON clm.clientFk = 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 c.isRelevant
|
|
AND clm.companyFk = vCompanyFk
|
|
UNION ALL
|
|
SELECT company_getCode(vCompanyFk),
|
|
'P',
|
|
s.id,
|
|
s.name,
|
|
s.name,
|
|
IFNULL(s.street, ''),
|
|
s.account,
|
|
TRIM(IF(co.code = LEFT(s.nif, 2), MID(s.nif, 3, LENGTH(s.nif) - 1), s.nif)),
|
|
IF(n.NacionCEE, TRIM(CONCAT(co.code, IF(co.code = LEFT(s.nif, 2), MID(s.nif, 3, LENGTH(s.nif) - 1), 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 IN('ES','EX'),
|
|
1,
|
|
IF((co.isUeeMember AND s.isVies), 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(iban, '')
|
|
FROM vn.supplier s
|
|
JOIN supplierLastThreeMonths pl ON pl.supplierFk = 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 pl.companyFk = vCompanyFk AND
|
|
s.isActive AND
|
|
s.nif <> ''
|
|
GROUP BY pl.supplierFk, pl.companyFk;
|
|
END
|