You can not select more than 25 topics Topics must start with a letter or number, can include dashes ('-') and can be up to 35 characters long.
 
 
 

365 lines
14 KiB

return: text
lang: plpgsql
src: |
DECLARE
file TEXT;
ok TEXT;
result TEXT;
BEGIN
INSERT INTO eco.t_divers (code, texte, valeur, description, valeur2)
SELECT
'REFFOUCTI',
'Référentiel fournisseur CTI',
'0',
'1=Génération référentiel fournisseur CTI',
''
WHERE 'REFFOUCTI' NOT IN (SELECT code FROM eco.t_divers);
INSERT INTO eco.t_divers (code, texte, valeur, description, valeur2)
SELECT
'REFARTCTI',
'Référentiel article CTI',
'0',
'1=Génération référentiel article CTI',
''
WHERE 'REFARTCTI' NOT IN (SELECT code FROM eco.t_divers);
-- Referentiel fournisseurs
IF EXISTS (SELECT valeur FROM eco.t_divers WHERE code = 'REFFOUCTI' AND valeur = '1') THEN
IF NOT EXISTS (SELECT * FROM pg_class WHERE relnamespace = pg_my_temp_schema() AND relname = 'w_cti_gen_referentiel') THEN
DROP TABLE IF EXISTS w_cti_gen_referentiel;
CREATE TEMP TABLE w_cti_gen_referentiel (
oid bigint,
code text,
texte text,
texte_court text,
texte_soundex text
);
END IF;
TRUNCATE w_cti_gen_referentiel;
INSERT INTO w_cti_gen_referentiel
SELECT oid, code, texte, texte_court, texte AS texte_soundex
FROM eco.t_fournisseurs
WHERE oid <> 0 AND
(fournisseur_reference_cti_id IS NULL OR
fournisseur_reference_cti_id = 0);
UPDATE w_cti_gen_referentiel
SET texte_soundex = trim(split_part(texte_soundex,'(',1))
WHERE texte_soundex like '%(%';
UPDATE w_cti_gen_referentiel
SET texte_soundex = translate(texte_soundex,'*.''"-;,/&','');
UPDATE w_cti_gen_referentiel
SET texte_soundex = rtrim(texte_soundex,'X')
WHERE texte_soundex like '%XX';
UPDATE w_cti_gen_referentiel
SET texte_soundex = ltrim(texte_soundex,'X')
WHERE texte_soundex like 'XX%';
UPDATE w_cti_gen_referentiel
SET texte_soundex = replace(texte_soundex,' SAS','')
WHERE texte_soundex like '% SAS%';
UPDATE w_cti_gen_referentiel
SET texte_soundex = replace(texte_soundex,' SA','')
WHERE texte_soundex like '% SA';
UPDATE w_cti_gen_referentiel
SET texte_soundex = replace(texte_soundex,' SA','')
WHERE texte_soundex like '% SARL';
UPDATE w_cti_gen_referentiel
SET texte_soundex = replace(texte_soundex,' FRANCE','')
WHERE texte_soundex like '% FRANCE';
UPDATE w_cti_gen_referentiel
SET texte_soundex = replace(texte_soundex,' ','')
WHERE texte_soundex like '% %';
INSERT INTO eco.t_fournisseur_reference_cti (code_original, code, texte, texte_court)
SELECT
texte_soundex AS code_original,
substr(texte_soundex,1,10),
MIN(texte) AS texte,
MIN(texte) AS texte_court
FROM w_cti_gen_referentiel
WHERE length(texte_soundex) > 1 AND
texte_soundex NOT IN (SELECT code_original FROM eco.t_fournisseur_reference_cti WHERE code_original IS NOT NULL)
GROUP BY 1
ORDER BY 1
;
UPDATE eco.t_fournisseurs
SET fournisseur_reference_cti_id = t_fournisseur_reference_cti.oid
FROM w_cti_gen_referentiel
JOIN eco.t_fournisseur_reference_cti ON t_fournisseur_reference_cti.code_original = texte_soundex
WHERE t_fournisseurs.oid = w_cti_gen_referentiel.oid;
UPDATE eco.t_fournisseur_reference_cti
SET code = ''
WHERE oid <> 0;
UPDATE eco.t_fournisseur_reference_cti
SET code = substr(code_original,1,4)
FROM
(SELECT substr(code_original,1,4) AS new_code
FROM eco.t_fournisseur_reference_cti
GROUP BY 1
HAVING count(*) = 1
) subview
WHERE oid <> 0 AND
substr(code_original,1,4) = new_code
;
UPDATE eco.t_fournisseur_reference_cti
SET code = substr(code_original,1,5)
FROM
(SELECT substr(code_original,1,5) AS new_code
FROM eco.t_fournisseur_reference_cti
GROUP BY 1
HAVING count(*) = 1
) subview
WHERE oid <> 0 AND
substr(code_original,1,5) = new_code AND
code = ''
;
UPDATE eco.t_fournisseur_reference_cti
SET code = substr(code_original,1,6)
FROM
(SELECT substr(code_original,1,6) AS new_code
FROM eco.t_fournisseur_reference_cti
GROUP BY 1
HAVING count(*) = 1
) subview
WHERE oid <> 0 AND
substr(code_original,1,6) = new_code AND
code = ''
;
UPDATE eco.t_fournisseur_reference_cti
SET code = substr(code_original,1,7)
FROM
(SELECT substr(code_original,1,7) AS new_code
FROM eco.t_fournisseur_reference_cti
GROUP BY 1
HAVING count(*) = 1
) subview
WHERE oid <> 0 AND
substr(code_original,1,7) = new_code AND
code = ''
;
UPDATE eco.t_fournisseur_reference_cti
SET code = substr(code_original,1,8)
FROM
(SELECT substr(code_original,1,8) AS new_code
FROM eco.t_fournisseur_reference_cti
GROUP BY 1
HAVING count(*) = 1
) subview
WHERE oid <> 0 AND
substr(code_original,1,8) = new_code AND
code = ''
;
PERFORM base.cti_execute(
'UPDATE eco.t_fournisseur_reference_cti
SET code = substr(code_original,1,8) || to_char(nb,''FM00'')
FROM
(
SELECT substr(code_original,1,8) AS new_code,
MAX(oid) AS max_id,
count(*) AS nb
FROM eco.t_fournisseur_reference_cti
WHERE code = ''''
GROUP BY 1
) subview
WHERE oid <> 0 AND
substr(code_original,1,8) = new_code AND
oid = max_id AND
code = ''''
',100);
UPDATE eco.t_fournisseurs SET
fournisseur_reference_cti_code = t_fournisseur_reference_cti.code,
fournisseur_reference_cti_texte = t_fournisseur_reference_cti.texte_court,
fournisseur_reference_cti_section_id = t_fournisseur_reference_cti.section_id,
fournisseur_reference_cti_section_code = t_fournisseur_reference_cti.section_code,
fournisseur_reference_cti_section_texte = t_fournisseur_reference_cti.section_texte
FROM eco.t_fournisseur_reference_cti
WHERE fournisseur_reference_cti_id = t_fournisseur_reference_cti.oid AND
(
fournisseur_reference_cti_code IS DISTINCT FROM t_fournisseur_reference_cti.code OR
fournisseur_reference_cti_texte IS DISTINCT FROM t_fournisseur_reference_cti.texte_court OR
fournisseur_reference_cti_section_id IS DISTINCT FROM t_fournisseur_reference_cti.section_id OR
fournisseur_reference_cti_section_code IS DISTINCT FROM t_fournisseur_reference_cti.section_code OR
fournisseur_reference_cti_section_texte IS DISTINCT FROM t_fournisseur_reference_cti.section_texte
);
INSERT INTO eco.p_oids (code_table, oid)
SELECT 'fournisseur_reference_cti', fournisseur_reference_cti_id
FROM eco.p_mouvements_articles JOIN eco.t_fournisseurs ON fournisseur_id = t_fournisseurs.oid
WHERE fournisseur_reference_cti_id <> 0 AND fournisseur_reference_cti_id IS NOT NULL AND fournisseur_reference_cti_id NOT IN (SELECT oid FROM eco.p_oids WHERE code_table = 'fournisseur_reference_cti')
GROUP BY 1,2;
INSERT INTO eco.p_oids (code_table, oid)
SELECT 'fournisseur_reference_cti', fournisseur_reference_cti_id
FROM eco.p_commandes JOIN eco.t_fournisseurs ON fournisseur_id = t_fournisseurs.oid
WHERE fournisseur_reference_cti_id IS NOT NULL AND fournisseur_reference_cti_id NOT IN (SELECT oid FROM eco.p_oids WHERE code_table = 'fournisseur_reference_cti')
GROUP BY 1,2;
END IF;
-- Referentiel articles
IF EXISTS (SELECT valeur FROM eco.t_divers WHERE code = 'REFARTCTI' AND valeur = '1') THEN
IF NOT EXISTS (SELECT * FROM pg_class WHERE relnamespace = pg_my_temp_schema() AND relname = 'w_cti_gen_referentiel') THEN
DROP TABLE IF EXISTS w_cti_gen_referentiel;
CREATE TEMP TABLE w_cti_gen_referentiel (
oid bigint,
code text,
texte text,
texte_court text,
texte_soundex text
);
END IF;
TRUNCATE w_cti_gen_referentiel;
INSERT INTO w_cti_gen_referentiel
SELECT oid, code, texte, texte_court, texte AS texte_soundex
FROM eco.t_articles
WHERE oid <> 0 AND
(article_reference_cti_id IS NULL OR
article_reference_cti_id = 0);
UPDATE w_cti_gen_referentiel
SET texte_soundex = trim(split_part(texte_soundex,'(',1))
WHERE texte_soundex like '%(%';
UPDATE w_cti_gen_referentiel
SET texte_soundex = translate(texte_soundex,'*.''"-;,/&=','');
UPDATE w_cti_gen_referentiel
SET texte_soundex = rtrim(texte_soundex,'X')
WHERE texte_soundex like '%XX';
UPDATE w_cti_gen_referentiel
SET texte_soundex = ltrim(texte_soundex,'X')
WHERE texte_soundex like 'XX%';
UPDATE w_cti_gen_referentiel
SET texte_soundex = replace(texte_soundex,' ','')
WHERE texte_soundex like '% %';
INSERT INTO eco.t_article_reference_cti (code_original, code, texte, texte_court)
SELECT
texte_soundex AS code_original,
substr(texte_soundex,1,10),
MIN(texte) AS texte,
MIN(texte) AS texte_court
FROM w_cti_gen_referentiel
WHERE length(texte_soundex) > 1 AND
texte_soundex NOT IN (SELECT code_original FROM eco.t_article_reference_cti WHERE code_original IS NOT NULL)
GROUP BY 1
ORDER BY 1
;
UPDATE eco.t_articles
SET article_reference_cti_id = t_article_reference_cti.oid
FROM w_cti_gen_referentiel
JOIN eco.t_article_reference_cti ON t_article_reference_cti.code_original = texte_soundex
WHERE t_articles.oid = w_cti_gen_referentiel.oid;
UPDATE eco.t_article_reference_cti
SET code = ''
WHERE oid <> 0;
UPDATE eco.t_article_reference_cti
SET code = substr(translate(code_original,'0123456789',''),1,4)
FROM
(SELECT substr(translate(code_original,'0123456789',''),1,4) AS new_code
FROM eco.t_article_reference_cti
WHERE length(translate(code_original,'0123456789','')) >= 4
GROUP BY 1
HAVING count(*) = 1
) subview
WHERE oid <> 0 AND
substr(translate(code_original,'0123456789',''),1,4) = new_code
;
UPDATE eco.t_article_reference_cti
SET code = substr(translate(code_original,'0123456789',''),1,5)
FROM
(SELECT substr(translate(code_original,'0123456789',''),1,5) AS new_code
FROM eco.t_article_reference_cti
WHERE length(translate(code_original,'0123456789','')) >= 4
GROUP BY 1
HAVING count(*) = 1
) subview
WHERE oid <> 0 AND
substr(translate(code_original,'0123456789',''),1,5) = new_code AND
code = ''
;
UPDATE eco.t_article_reference_cti
SET code = substr(translate(code_original,'0123456789',''),1,6)
FROM
(SELECT substr(translate(code_original,'0123456789',''),1,6) AS new_code
FROM eco.t_article_reference_cti
WHERE length(translate(code_original,'0123456789','')) >= 4
GROUP BY 1
HAVING count(*) = 1
) subview
WHERE oid <> 0 AND
substr(translate(code_original,'0123456789',''),1,6) = new_code AND
code = ''
;
UPDATE eco.t_article_reference_cti
SET code = substr(translate(code_original,'0123456789',''),1,7)
FROM
(SELECT substr(translate(code_original,'0123456789',''),1,7) AS new_code
FROM eco.t_article_reference_cti
WHERE length(translate(code_original,'0123456789','')) >= 4
GROUP BY 1
HAVING count(*) = 1
) subview
WHERE oid <> 0 AND
substr(translate(code_original,'0123456789',''),1,7) = new_code AND
code = ''
;
PERFORM base.cti_execute(
'UPDATE eco.t_article_reference_cti
SET code = substr(translate(code_original,''0123456789'',''''),1,7) || to_char(nb,''FM00'')
FROM
(
SELECT substr(translate(code_original,''0123456789'',''''),1,7) AS new_code,
MAX(oid) AS max_id,
count(*) AS nb
FROM eco.t_article_reference_cti
WHERE length(translate(code_original,''0123456789'','''')) >= 4 AND
code = ''''
GROUP BY 1
) subview
WHERE oid <> 0 AND
substr(translate(code_original,''0123456789'',''''),1,7) = new_code AND
oid = max_id AND
code = ''''',500)
;
PERFORM base.cti_execute(
'UPDATE eco.t_article_reference_cti
SET code = substr(code_original,1,7) || to_char(nb,''FM00'')
FROM
(
SELECT substr(code_original,1,7) AS new_code,
MAX(oid) AS max_id,
count(*) AS nb
FROM eco.t_article_reference_cti
WHERE code = ''''
GROUP BY 1
) subview
WHERE oid <> 0 AND
substr(code_original,1,7) = new_code AND
oid = max_id AND
code = ''''',500)
;
UPDATE eco.t_articles SET
article_reference_cti_code = t_article_reference_cti.code,
article_reference_cti_texte = t_article_reference_cti.texte_court,
article_reference_cti_section_id = t_article_reference_cti.section_id,
article_reference_cti_section_code = t_article_reference_cti.section_code,
article_reference_cti_section_texte = t_article_reference_cti.section_texte
FROM eco.t_article_reference_cti
WHERE article_reference_cti_id = t_article_reference_cti.oid AND
(
article_reference_cti_code IS DISTINCT FROM t_article_reference_cti.code OR
article_reference_cti_texte IS DISTINCT FROM t_article_reference_cti.texte_court OR
article_reference_cti_section_id IS DISTINCT FROM t_article_reference_cti.section_id OR
article_reference_cti_section_code IS DISTINCT FROM t_article_reference_cti.section_code OR
article_reference_cti_section_texte IS DISTINCT FROM t_article_reference_cti.section_texte
);
INSERT INTO eco.p_oids (code_table, oid)
SELECT 'article_reference_cti', article_reference_cti_id
FROM eco.p_mouvements_articles JOIN eco.t_articles ON article_id = t_articles.oid
WHERE article_reference_cti_id IS NOT NULL AND article_reference_cti_id NOT IN (SELECT oid FROM eco.p_oids WHERE code_table = 'article_reference_cti')
GROUP BY 1,2;
INSERT INTO eco.p_oids (code_table, oid)
SELECT 'article_reference_cti', article_reference_cti_id
FROM eco.p_lignes_commandes JOIN eco.t_articles ON article_id = t_articles.oid
WHERE article_reference_cti_id IS NOT NULL AND article_reference_cti_id NOT IN (SELECT oid FROM eco.p_oids WHERE code_table = 'article_reference_cti')
GROUP BY 1,2;
END IF;
RETURN 'OK';
END;