|
|
<?xml version="1.0" encoding="ISO-8859-1"?>
|
|
|
<ROOT>
|
|
|
<NODE name="INIT" label="INITIALISATIONS">
|
|
|
|
|
|
<NODE label="Tables Articles">
|
|
|
|
|
|
<sqlcmd><![CDATA[
|
|
|
|
|
|
-- Table articles avec autres caractéristiques
|
|
|
DROP TABLE IF EXISTS w_ARTICLES;
|
|
|
CREATE TEMP TABLE w_ARTICLES AS
|
|
|
SELECT ARTICLES.*,
|
|
|
''::text AS UCD13,
|
|
|
COALESCE(ARTICLES_LIBEL.LIBELLE_CONCAT,ARTICLES.CODE_ARTICLE) AS LIBELLE_CONCAT,
|
|
|
COALESCE(CATEG_1,'') AS CATEG_1,
|
|
|
COALESCE(CATEG_2,'') AS CATEG_2,
|
|
|
COALESCE(CATEG_3,'') AS CATEG_3,
|
|
|
FAMILLE::text AS FAMILLE_CODE_CTI,
|
|
|
RUBRIQUE_TARIF::text AS RUBRIQUE_TARIF_CODE_CTI,
|
|
|
COALESCE(CATEG_1,'')::text AS CATEG_1_CODE_CTI,
|
|
|
COALESCE(CATEG_2,'')::text AS CATEG_2_CODE_CTI,
|
|
|
COALESCE(CATEG_3,'')::text AS CATEG_3_CODE_CTI
|
|
|
FROM prod_sigems.ARTICLES
|
|
|
LEFT JOIN prod_sigems.ARTICLES_LIBEL ON ARTICLES.CODE_ARTICLE = ARTICLES_LIBEL.CODE_ARTICLE
|
|
|
LEFT JOIN prod_sigems.ART_X ON ARTICLES.CODE_ARTICLE = ART_X.CODE_ARTICLE
|
|
|
;
|
|
|
|
|
|
UPDATE w_ARTICLES SET
|
|
|
UCD13 = UCD,
|
|
|
UCD = substr(UCD,6,7)
|
|
|
WHERE length(UCD) = 13 AND
|
|
|
UCD LIKE '34008%'
|
|
|
;
|
|
|
|
|
|
-- LPP
|
|
|
INSERT INTO base.t_lpp (code, texte, texte_court)
|
|
|
SELECT CODE_TIPS, MAX(NOM_COURT), MAX(NOM_COURT)
|
|
|
FROM prod_sigems.LPP_FICHE
|
|
|
WHERE CODE_TIPS NOT IN (SELECT code FROM base.t_lpp)
|
|
|
GROUP BY 1
|
|
|
;
|
|
|
|
|
|
INSERT INTO base.t_lpp (code, texte, texte_court)
|
|
|
SELECT CODE_TIPS, CODE_TIPS, CODE_TIPS
|
|
|
FROM w_ARTICLES
|
|
|
WHERE CODE_TIPS <> '' AND
|
|
|
CODE_TIPS NOT IN (SELECT code FROM base.t_lpp)
|
|
|
GROUP BY 1,2,3;
|
|
|
|
|
|
-- UCD
|
|
|
INSERT INTO base.t_ucd (code, texte, texte_court, laboratoire_texte, conditionnement_texte)
|
|
|
SELECT CODE, MAX(LIB_LONG), MAX(LIB_LONG), MAX(LABO), MAX(LIB_COND)
|
|
|
FROM prod_sigems.UCD_FICHE_GENE
|
|
|
WHERE CODE NOT IN (SELECT code FROM base.t_ucd)
|
|
|
GROUP BY 1;
|
|
|
|
|
|
INSERT INTO base.t_ucd (code, texte, texte_court)
|
|
|
SELECT UCD, UCD, UCD
|
|
|
FROM w_ARTICLES
|
|
|
WHERE UCD <> '' AND
|
|
|
UCD NOT IN (SELECT code FROM base.t_ucd) AND
|
|
|
length(UCD) = 7
|
|
|
GROUP BY 1,2,3;
|
|
|
|
|
|
-- ATC
|
|
|
INSERT INTO eco.t_classification_atc(code_original, code, texte, texte_court )
|
|
|
SELECT UPPER(CODE_5), UPPER(MAX(CODE_5)), MAX(LIBELLE_5), MAX(LIBELLE_5)
|
|
|
FROM prod_sigems.ATC
|
|
|
LEFT JOIN eco.t_classification_atc ON code_original = UPPER(CODE_5)
|
|
|
WHERE CODE_5 <> '' AND
|
|
|
code_original IS NULL
|
|
|
GROUP BY 1
|
|
|
ORDER BY 1;
|
|
|
|
|
|
INSERT INTO eco.t_classification_atc(code_original, code, texte, texte_court )
|
|
|
SELECT UPPER(CODE_4), UPPER(MAX(CODE_4)), MAX(LIBELLE_4), MAX(LIBELLE_4)
|
|
|
FROM prod_sigems.ATC
|
|
|
LEFT JOIN eco.t_classification_atc ON code_original = UPPER(CODE_4)
|
|
|
WHERE CODE_4 <> '' AND
|
|
|
code_original IS NULL
|
|
|
GROUP BY 1
|
|
|
ORDER BY 1;
|
|
|
|
|
|
INSERT INTO eco.t_classification_atc(code_original, code, texte, texte_court )
|
|
|
SELECT UPPER(CODE_3), UPPER(MAX(CODE_3)), MAX(LIBELLE_3), MAX(LIBELLE_3)
|
|
|
FROM prod_sigems.ATC
|
|
|
LEFT JOIN eco.t_classification_atc ON code_original = UPPER(CODE_3)
|
|
|
WHERE CODE_3 <> '' AND
|
|
|
code_original IS NULL
|
|
|
GROUP BY 1
|
|
|
ORDER BY 1;
|
|
|
|
|
|
|
|
|
INSERT INTO eco.t_classification_atc(code_original, code, texte, texte_court )
|
|
|
SELECT UPPER(CODE_2), UPPER(MAX(CODE_2)), MAX(LIBELLE_2), MAX(LIBELLE_2)
|
|
|
FROM prod_sigems.ATC
|
|
|
LEFT JOIN eco.t_classification_atc ON code_original = UPPER(CODE_2)
|
|
|
WHERE CODE_2 <> '' AND
|
|
|
code_original IS NULL
|
|
|
GROUP BY 1
|
|
|
ORDER BY 1;
|
|
|
|
|
|
INSERT INTO eco.t_classification_atc(code_original, code, texte, texte_court )
|
|
|
SELECT UPPER(CODE_1), UPPER(MAX(CODE_1)), MAX(LIBELLE_1), MAX(LIBELLE_1)
|
|
|
FROM prod_sigems.ATC
|
|
|
LEFT JOIN eco.t_classification_atc ON code_original = UPPER(CODE_1)
|
|
|
WHERE CODE_1 <> '' AND
|
|
|
code_original IS NULL
|
|
|
GROUP BY 1
|
|
|
ORDER BY 1;
|
|
|
|
|
|
-- Standard ATC
|
|
|
SELECT eco.cti_reorganize_classification_atc();
|
|
|
|
|
|
|
|
|
-- Comptes
|
|
|
INSERT INTO eco.t_compte(code, texte, texte_court, code_original)
|
|
|
SELECT
|
|
|
NUM,
|
|
|
MAX(trim(INT1 || ' ' || INT2)),
|
|
|
MAX(trim(INT1 || ' ' || INT2)),
|
|
|
NUM
|
|
|
FROM prod_sigems.COMPTE
|
|
|
JOIN prod_sigems.ARTICLES ON ARTICLES.compte_general = compte.num
|
|
|
JOIN prod_sigems.LA_SOCIETE ON LA_SOCIETE.code_societe = compte.ste AND LA_SOCIETE.groupe = ARTICLES.groupe
|
|
|
WHERE 1=1
|
|
|
AND NUM <> ''
|
|
|
AND NUM NOT IN (SELECT code_original FROM eco.t_compte WHERE code_original IS NOT NULL)
|
|
|
GROUP BY 1
|
|
|
ORDER BY 1
|
|
|
;
|
|
|
|
|
|
WITH new_label AS (
|
|
|
SELECT
|
|
|
num as code_original,
|
|
|
MAX(trim(INT1 || ' ' || INT2)) as texte
|
|
|
FROM prod_sigems.COMPTE
|
|
|
JOIN prod_sigems.ARTICLES ON ARTICLES.compte_general = compte.num
|
|
|
JOIN prod_sigems.LA_SOCIETE ON LA_SOCIETE.code_societe = compte.ste AND LA_SOCIETE.groupe = ARTICLES.groupe
|
|
|
WHERE NUM <> ''
|
|
|
GROUP BY 1
|
|
|
)
|
|
|
UPDATE eco.t_compte
|
|
|
SET
|
|
|
texte = new_label.texte,
|
|
|
texte_court = new_label.texte
|
|
|
FROM new_label
|
|
|
WHERE 1=1
|
|
|
AND t_compte.code_original = new_label.code_original
|
|
|
AND (t_compte.texte IS DISTINCT FROM new_label.texte OR t_compte.texte_court IS DISTINCT FROM new_label.texte)
|
|
|
;
|
|
|
|
|
|
|
|
|
-- Types d'articles
|
|
|
INSERT INTO eco.t_types_articles(code, texte, texte_court, code_original)
|
|
|
SELECT CODE, NOM, NOM, CODE
|
|
|
FROM prod_sigems.GROUPE
|
|
|
WHERE CODE <> '' AND
|
|
|
CODE IN (SELECT GROUPE FROM prod_sigems.ARTICLES) AND
|
|
|
CODE NOT IN (SELECT code_original FROM eco.t_types_articles WHERE code_original IS NOT NULL)
|
|
|
GROUP BY 1,2,3,4
|
|
|
ORDER BY 1;
|
|
|
|
|
|
|
|
|
-- Familles d'articles
|
|
|
DROP TABLE IF EXISTS w_FAMILLE;
|
|
|
CREATE TEMP TABLE w_FAMILLE AS
|
|
|
SELECT FAMILLE.CODE::text,
|
|
|
UPPER(FAMILLE.CODE)::text AS CODE_CTI,
|
|
|
FAMILLE.GROUPE::text,
|
|
|
FAMILLE.CODE::text AS GROUPE_CODE,
|
|
|
MAX(FAMILLE.LIBELLE)::text AS LIBELLE
|
|
|
FROM prod_sigems.FAMILLE
|
|
|
JOIN w_ARTICLES ARTICLES ON
|
|
|
FAMILLE.GROUPE = ARTICLES.GROUPE AND
|
|
|
FAMILLE.CODE = ARTICLES.FAMILLE
|
|
|
WHERE CODE <> ''
|
|
|
GROUP BY 1,2,3
|
|
|
ORDER BY 1,2;
|
|
|
|
|
|
UPDATE w_FAMILLE SET
|
|
|
CODE_CTI = CODE_CTI || ' (' || GROUPE || ')',
|
|
|
GROUPE_CODE = CODE || '-' || GROUPE
|
|
|
WHERE CODE IN (SELECT CODE FROM w_FAMILLE GROUP BY 1 HAVING COUNT(DISTINCT LIBELLE) > 1);
|
|
|
|
|
|
INSERT INTO eco.t_familles_articles(code, texte, texte_court, code_original)
|
|
|
SELECT CODE_CTI, LIBELLE, LIBELLE, GROUPE_CODE
|
|
|
FROM w_FAMILLE
|
|
|
WHERE CODE <> '' AND
|
|
|
GROUPE_CODE NOT IN (SELECT code_original FROM eco.t_familles_articles WHERE code_original IS NOT NULL)
|
|
|
GROUP BY 1,2,3,4
|
|
|
ORDER BY 1;
|
|
|
|
|
|
UPDATE eco.t_familles_articles
|
|
|
SET texte = LIBELLE, texte_court = LIBELLE
|
|
|
FROM w_FAMILLE
|
|
|
WHERE w_FAMILLE.GROUPE_CODE = code_original AND
|
|
|
(texte IS DISTINCT FROM LIBELLE OR
|
|
|
texte_court IS DISTINCT FROM LIBELLE);
|
|
|
|
|
|
UPDATE w_ARTICLES SET
|
|
|
FAMILLE_CODE_CTI = w_FAMILLE.CODE_CTI
|
|
|
FROM w_FAMILLE
|
|
|
WHERE w_FAMILLE.GROUPE = w_ARTICLES.GROUPE AND
|
|
|
w_FAMILLE.CODE = w_ARTICLES.FAMILLE AND
|
|
|
FAMILLE_CODE_CTI IS DISTINCT FROM w_FAMILLE.CODE_CTI;
|
|
|
|
|
|
|
|
|
-- Sous familles
|
|
|
DROP TABLE IF EXISTS w_RUBRIQUE_TARIF;
|
|
|
CREATE TEMP TABLE w_RUBRIQUE_TARIF AS
|
|
|
SELECT RUBRIQUE_TARIF.CODE::text,
|
|
|
UPPER(RUBRIQUE_TARIF.CODE)::text AS CODE_CTI,
|
|
|
RUBRIQUE_TARIF.GROUPE::text,
|
|
|
RUBRIQUE_TARIF.CODE::text AS GROUPE_CODE,
|
|
|
MAX(RUBRIQUE_TARIF.LIBELLE)::text AS LIBELLE
|
|
|
FROM prod_sigems.RUBRIQUE_TARIF
|
|
|
JOIN w_ARTICLES ARTICLES ON
|
|
|
RUBRIQUE_TARIF.GROUPE = ARTICLES.GROUPE AND
|
|
|
RUBRIQUE_TARIF.CODE = ARTICLES.RUBRIQUE_TARIF
|
|
|
WHERE CODE <> ''
|
|
|
GROUP BY 1,2,3
|
|
|
ORDER BY 1,2;
|
|
|
|
|
|
UPDATE w_RUBRIQUE_TARIF SET
|
|
|
CODE_CTI = CODE_CTI || ' (' || GROUPE || ')',
|
|
|
GROUPE_CODE = CODE || '-' || GROUPE
|
|
|
WHERE CODE IN (SELECT CODE FROM w_RUBRIQUE_TARIF GROUP BY 1 HAVING COUNT(DISTINCT LIBELLE) > 1);
|
|
|
|
|
|
INSERT INTO eco.t_sous_familles_articles(code, texte, texte_court, code_original)
|
|
|
SELECT CODE_CTI, LIBELLE, LIBELLE, GROUPE_CODE
|
|
|
FROM w_RUBRIQUE_TARIF
|
|
|
WHERE CODE <> '' AND
|
|
|
GROUPE_CODE NOT IN (SELECT code_original FROM eco.t_sous_familles_articles WHERE code_original IS NOT NULL)
|
|
|
GROUP BY 1,2,3,4
|
|
|
ORDER BY 1;
|
|
|
|
|
|
UPDATE eco.t_sous_familles_articles
|
|
|
SET texte = LIBELLE, texte_court = LIBELLE
|
|
|
FROM w_RUBRIQUE_TARIF
|
|
|
WHERE w_RUBRIQUE_TARIF.GROUPE_CODE = code_original AND
|
|
|
(texte IS DISTINCT FROM LIBELLE OR
|
|
|
texte_court IS DISTINCT FROM LIBELLE);
|
|
|
|
|
|
UPDATE w_ARTICLES SET
|
|
|
RUBRIQUE_TARIF_CODE_CTI = w_RUBRIQUE_TARIF.CODE_CTI
|
|
|
FROM w_RUBRIQUE_TARIF
|
|
|
WHERE w_RUBRIQUE_TARIF.GROUPE = w_ARTICLES.GROUPE AND
|
|
|
w_RUBRIQUE_TARIF.CODE = w_ARTICLES.RUBRIQUE_TARIF AND
|
|
|
RUBRIQUE_TARIF_CODE_CTI IS DISTINCT FROM w_RUBRIQUE_TARIF.CODE_CTI;
|
|
|
|
|
|
-- Catégories
|
|
|
DROP TABLE IF EXISTS w_CATEG_1;
|
|
|
CREATE TEMP TABLE w_CATEG_1 AS
|
|
|
SELECT CATEG_1.CODE::text,
|
|
|
UPPER(CATEG_1.CODE)::text AS CODE_CTI,
|
|
|
CATEG_1.GROUPE::text,
|
|
|
CATEG_1.CODE::text AS GROUPE_CODE,
|
|
|
MAX(CATEG_1.LIBELLE)::text AS LIBELLE
|
|
|
FROM prod_sigems.CATEG_1
|
|
|
JOIN w_ARTICLES ARTICLES ON
|
|
|
CATEG_1.GROUPE = ARTICLES.GROUPE AND
|
|
|
CATEG_1.CODE = ARTICLES.CATEG_1
|
|
|
WHERE CODE <> ''
|
|
|
GROUP BY 1,2,3
|
|
|
ORDER BY 1,2;
|
|
|
|
|
|
UPDATE w_CATEG_1 SET
|
|
|
CODE_CTI = CODE_CTI || ' (' || GROUPE || ')',
|
|
|
GROUPE_CODE = CODE || '-' || GROUPE
|
|
|
WHERE CODE IN (SELECT CODE FROM w_CATEG_1 GROUP BY 1 HAVING COUNT(DISTINCT LIBELLE) > 1);
|
|
|
|
|
|
INSERT INTO eco.t_categories_articles(code, texte, texte_court, code_original)
|
|
|
SELECT CODE_CTI, LIBELLE, substr(LIBELLE,1,50), GROUPE_CODE
|
|
|
FROM w_CATEG_1
|
|
|
WHERE CODE <> '' AND
|
|
|
GROUPE_CODE NOT IN (SELECT code_original FROM eco.t_categories_articles WHERE code_original IS NOT NULL)
|
|
|
GROUP BY 1,2,3,4
|
|
|
ORDER BY 1;
|
|
|
|
|
|
UPDATE eco.t_categories_articles
|
|
|
SET texte = LIBELLE, texte_court = substr(LIBELLE,1,50)
|
|
|
FROM w_CATEG_1
|
|
|
WHERE w_CATEG_1.GROUPE_CODE = code_original AND
|
|
|
(texte IS DISTINCT FROM LIBELLE OR
|
|
|
texte_court IS DISTINCT FROM substr(LIBELLE,1,50));
|
|
|
|
|
|
UPDATE w_ARTICLES SET
|
|
|
CATEG_1_CODE_CTI = w_CATEG_1.CODE_CTI
|
|
|
FROM w_CATEG_1
|
|
|
WHERE w_CATEG_1.GROUPE = w_ARTICLES.GROUPE AND
|
|
|
w_CATEG_1.CODE = w_ARTICLES.CATEG_1 AND
|
|
|
CATEG_1_CODE_CTI IS DISTINCT FROM w_CATEG_1.CODE_CTI;
|
|
|
|
|
|
-- Sous catégories (2 ou 3 selon paramètre)
|
|
|
DROP TABLE IF EXISTS w_CATEG_2;
|
|
|
CREATE TEMP TABLE w_CATEG_2 AS
|
|
|
SELECT ARTICLES.CATEG_2::text AS CODE,
|
|
|
UPPER(ARTICLES.CATEG_2)::text AS CODE_CTI,
|
|
|
COALESCE(CATEG_2.GROUPE,'')::text AS GROUPE,
|
|
|
ARTICLES.CATEG_2::text AS GROUPE_CODE,
|
|
|
MAX(COALESCE(CATEG_2.LIBELLE,ARTICLES.CATEG_2))::text AS LIBELLE
|
|
|
FROM w_ARTICLES ARTICLES
|
|
|
LEFT JOIN prod_sigems.CATEG_2 ON
|
|
|
CATEG_2.GROUPE = ARTICLES.GROUPE AND
|
|
|
CATEG_2.CODE = ARTICLES.CATEG_2
|
|
|
WHERE ARTICLES.CATEG_2 <> ''
|
|
|
GROUP BY 1,2,3
|
|
|
ORDER BY 1,2;
|
|
|
|
|
|
UPDATE w_CATEG_2 SET
|
|
|
CODE_CTI = CODE_CTI || ' (' || GROUPE || ')',
|
|
|
GROUPE_CODE = CODE || '-' || GROUPE
|
|
|
WHERE CODE IN (SELECT CODE FROM w_CATEG_2 GROUP BY 1 HAVING COUNT(DISTINCT LIBELLE) > 1);
|
|
|
|
|
|
DROP TABLE IF EXISTS w_CATEG_3;
|
|
|
CREATE TEMP TABLE w_CATEG_3 AS
|
|
|
SELECT ARTICLES.CATEG_3::text AS CODE,
|
|
|
UPPER(ARTICLES.CATEG_3)::text AS CODE_CTI,
|
|
|
COALESCE(CATEG_3.GROUPE,'')::text AS GROUPE,
|
|
|
ARTICLES.CATEG_3::text AS GROUPE_CODE,
|
|
|
MAX(COALESCE(CATEG_3.LIBELLE,ARTICLES.CATEG_3))::text AS LIBELLE
|
|
|
FROM w_ARTICLES ARTICLES
|
|
|
LEFT JOIN prod_sigems.CATEG_3 ON
|
|
|
CATEG_3.GROUPE = ARTICLES.GROUPE AND
|
|
|
CATEG_3.CODE = ARTICLES.CATEG_3
|
|
|
WHERE ARTICLES.CATEG_3 <> ''
|
|
|
GROUP BY 1,2,3
|
|
|
ORDER BY 1,2;
|
|
|
|
|
|
UPDATE w_CATEG_3 SET
|
|
|
CODE_CTI = CODE_CTI || ' (' || GROUPE || ')',
|
|
|
GROUPE_CODE = CODE || '-' || GROUPE
|
|
|
WHERE CODE IN (SELECT CODE FROM w_CATEG_3 GROUP BY 1 HAVING COUNT(DISTINCT LIBELLE) > 1);
|
|
|
|
|
|
-- Origine de la sous-catégorie
|
|
|
INSERT INTO eco.t_divers (code, texte, valeur, description)
|
|
|
SELECT
|
|
|
'SIGEMS_SCA_SRC'::text,
|
|
|
'Origine de la sous-catégorie'::text,
|
|
|
'CATEG_3'::text,
|
|
|
'CATEG_2, CATEG_3'::text
|
|
|
WHERE 'SIGEMS_SCA_SRC'::text NOT IN (SELECT code FROM eco.t_divers)
|
|
|
;
|
|
|
|
|
|
INSERT INTO eco.t_sous_categories_articles(code, texte, texte_court, code_original)
|
|
|
SELECT CODE_CTI, LIBELLE, substr(LIBELLE,1,50), GROUPE_CODE
|
|
|
FROM w_CATEG_2
|
|
|
JOIN eco.t_divers ON t_divers.code = 'SIGEMS_SCA_SRC' AND t_divers.valeur <> 'CATEG_3'
|
|
|
WHERE w_CATEG_2.CODE <> '' AND
|
|
|
w_CATEG_2.GROUPE_CODE NOT IN (SELECT code_original FROM eco.t_sous_categories_articles WHERE code_original IS NOT NULL)
|
|
|
GROUP BY 1,2,3,4
|
|
|
ORDER BY 1;
|
|
|
|
|
|
INSERT INTO eco.t_sous_categories_articles(code, texte, texte_court, code_original)
|
|
|
SELECT CODE_CTI, LIBELLE, substr(LIBELLE,1,50), GROUPE_CODE
|
|
|
FROM w_CATEG_3
|
|
|
JOIN eco.t_divers ON t_divers.code = 'SIGEMS_SCA_SRC' AND t_divers.valeur = 'CATEG_3'
|
|
|
WHERE w_CATEG_3.CODE <> '' AND
|
|
|
w_CATEG_3.GROUPE_CODE NOT IN (SELECT code_original FROM eco.t_sous_categories_articles WHERE code_original IS NOT NULL)
|
|
|
GROUP BY 1,2,3,4
|
|
|
ORDER BY 1;
|
|
|
|
|
|
UPDATE eco.t_sous_categories_articles
|
|
|
SET texte = LIBELLE, texte_court = substr(LIBELLE,1,50)
|
|
|
FROM w_CATEG_2
|
|
|
JOIN eco.t_divers ON t_divers.code = 'SIGEMS_SCA_SRC' AND t_divers.valeur <> 'CATEG_3'
|
|
|
WHERE w_CATEG_2.GROUPE_CODE = code_original AND
|
|
|
(
|
|
|
t_sous_categories_articles.texte IS DISTINCT FROM LIBELLE OR
|
|
|
t_sous_categories_articles.texte_court IS DISTINCT FROM substr(LIBELLE,1,50)
|
|
|
)
|
|
|
;
|
|
|
|
|
|
|
|
|
UPDATE eco.t_sous_categories_articles
|
|
|
SET texte = LIBELLE, texte_court = substr(LIBELLE,1,50)
|
|
|
FROM w_CATEG_3
|
|
|
JOIN eco.t_divers ON t_divers.code = 'SIGEMS_SCA_SRC' AND t_divers.valeur = 'CATEG_3'
|
|
|
WHERE w_CATEG_3.GROUPE_CODE = code_original AND
|
|
|
(
|
|
|
t_sous_categories_articles.texte IS DISTINCT FROM LIBELLE OR
|
|
|
t_sous_categories_articles.texte_court IS DISTINCT FROM substr(LIBELLE,1,50)
|
|
|
)
|
|
|
;
|
|
|
|
|
|
UPDATE w_ARTICLES SET
|
|
|
CATEG_2_CODE_CTI = w_CATEG_2.CODE_CTI
|
|
|
FROM w_CATEG_2
|
|
|
WHERE w_CATEG_2.GROUPE = w_ARTICLES.GROUPE AND
|
|
|
w_CATEG_2.CODE = w_ARTICLES.CATEG_2 AND
|
|
|
CATEG_2_CODE_CTI IS DISTINCT FROM w_CATEG_2.CODE_CTI
|
|
|
;
|
|
|
|
|
|
UPDATE w_ARTICLES SET
|
|
|
CATEG_3_CODE_CTI = w_CATEG_3.CODE_CTI
|
|
|
FROM w_CATEG_3
|
|
|
WHERE w_CATEG_3.GROUPE = w_ARTICLES.GROUPE AND
|
|
|
w_CATEG_3.CODE = w_ARTICLES.CATEG_3 AND
|
|
|
CATEG_3_CODE_CTI IS DISTINCT FROM w_CATEG_3.CODE_CTI
|
|
|
;
|
|
|
|
|
|
-- Articles
|
|
|
|
|
|
INSERT INTO eco.t_articles(code, texte, texte_court, code_original)
|
|
|
SELECT CODE_ARTICLE, LIBELLE_CONCAT, substr(LIBELLE_CONCAT,1,50), CODE_ARTICLE
|
|
|
FROM w_ARTICLES ARTICLES
|
|
|
LEFT JOIN eco.t_articles ON (code_original = CODE_ARTICLE)
|
|
|
WHERE code_original IS NULL;
|
|
|
|
|
|
|
|
|
UPDATE eco.t_articles
|
|
|
SET
|
|
|
texte = LIBELLE_CONCAT,
|
|
|
texte_court = substr(LIBELLE_CONCAT,1,50)
|
|
|
FROM w_ARTICLES ARTICLES
|
|
|
WHERE code_original = CODE_ARTICLE
|
|
|
AND (
|
|
|
texte IS DISTINCT FROM LIBELLE_CONCAT OR
|
|
|
texte_court IS DISTINCT FROM substr(LIBELLE_CONCAT,1,50));
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
UPDATE eco.t_articles SET
|
|
|
type_id = COALESCE(t_types_articles.oid,0),
|
|
|
famille_id = COALESCE(t_familles_articles.oid,0),
|
|
|
sous_famille_id = COALESCE(t_sous_familles_articles.oid,0),
|
|
|
categorie_id = COALESCE(t_categories_articles.oid,0),
|
|
|
sous_categorie_id = COALESCE(t_sous_categories_articles.oid,0),
|
|
|
classification_atc_id = COALESCE(t_classification_atc.oid,0),
|
|
|
unite_stockage_id = COALESCE(t_unites_stockage.oid,0),
|
|
|
unite_distribution_id = COALESCE(t_unites_distribution.oid,0),
|
|
|
lpp_id = COALESCE(t_lpp.oid,0),
|
|
|
ucd_id = COALESCE(t_ucd.oid,0),
|
|
|
code_ucd13 = ARTICLES.UCD13
|
|
|
FROM w_ARTICLES ARTICLES
|
|
|
JOIN eco.t_divers ON t_divers.code = 'SIGEMS_SCA_SRC'
|
|
|
LEFT JOIN eco.t_familles_articles ON FAMILLE_CODE_CTI = upper(t_familles_articles.code_original)
|
|
|
LEFT JOIN eco.t_sous_familles_articles ON RUBRIQUE_TARIF_CODE_CTI = upper(t_sous_familles_articles.code_original)
|
|
|
LEFT JOIN eco.t_types_articles ON GROUPE = upper(t_types_articles.code_original)
|
|
|
LEFT JOIN eco.t_classification_atc ON ATC = upper(t_classification_atc.code_original)
|
|
|
LEFT JOIN eco.t_categories_articles ON ARTICLES.CATEG_1_CODE_CTI = upper(t_categories_articles.code_original)
|
|
|
LEFT JOIN eco.t_sous_categories_articles ON
|
|
|
(
|
|
|
t_divers.valeur <> 'CATEG_3' AND ARTICLES.CATEG_2_CODE_CTI = upper(t_sous_categories_articles.code_original) OR
|
|
|
t_divers.valeur = 'CATEG_3' AND ARTICLES.CATEG_3_CODE_CTI = upper(t_sous_categories_articles.code_original)
|
|
|
)
|
|
|
LEFT JOIN eco.t_unites t_unites_stockage ON UNITE_DISTRI = upper(t_unites_stockage.code_original)
|
|
|
LEFT JOIN eco.t_unites t_unites_distribution ON UNITE_CONSO = upper(t_unites_distribution.code_original)
|
|
|
LEFT JOIN base.t_lpp ON CODE_TIPS = t_lpp.code
|
|
|
LEFT JOIN base.t_ucd ON UCD = t_ucd.code
|
|
|
WHERE
|
|
|
t_articles.code_original = ARTICLES.CODE_ARTICLE AND
|
|
|
(
|
|
|
t_articles.type_id IS DISTINCT FROM COALESCE(t_types_articles.oid,0) OR
|
|
|
t_articles.famille_id IS DISTINCT FROM COALESCE(t_familles_articles.oid,0) OR
|
|
|
t_articles.sous_famille_id IS DISTINCT FROM COALESCE(t_sous_familles_articles.oid,0) OR
|
|
|
t_articles.categorie_id IS DISTINCT FROM COALESCE(t_categories_articles.oid,0) OR
|
|
|
t_articles.sous_categorie_id IS DISTINCT FROM COALESCE(t_sous_categories_articles.oid,0) OR
|
|
|
t_articles.classification_atc_id IS DISTINCT FROM COALESCE(t_classification_atc.oid,0) OR
|
|
|
t_articles.unite_stockage_id IS DISTINCT FROM COALESCE(t_unites_stockage.oid,0) OR
|
|
|
t_articles.unite_distribution_id IS DISTINCT FROM COALESCE(t_unites_distribution.oid,0) OR
|
|
|
lpp_id IS DISTINCT FROM COALESCE(t_lpp.oid,0) OR
|
|
|
ucd_id IS DISTINCT FROM COALESCE(t_ucd.oid,0) OR
|
|
|
code_ucd13 IS DISTINCT FROM ARTICLES.UCD13
|
|
|
)
|
|
|
;
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
UPDATE eco.t_articles SET
|
|
|
compte_id = COALESCE(t_compte.oid,0)
|
|
|
FROM w_ARTICLES ARTICLES
|
|
|
LEFT JOIN eco.t_compte ON COMPTE_GENERAL = t_compte.code_original
|
|
|
WHERE
|
|
|
t_articles.code_original = CODE_ARTICLE AND
|
|
|
(
|
|
|
t_articles.compte_id IS DISTINCT FROM COALESCE(t_compte.oid,0)
|
|
|
);
|
|
|
|
|
|
UPDATE eco.t_articles SET compte_id = 0 WHERE compte_id IS NULL;
|
|
|
|
|
|
|
|
|
UPDATE eco.t_articles SET
|
|
|
gere_en_stock = CASE WHEN ARTICLES.STOCKABLE = 'O' AND ARTICLES.STOCK_EN_DEPOT <> 'O' THEN '1' ELSE '0' END,
|
|
|
stock_en_depot = CASE WHEN ARTICLES.STOCKABLE = 'O' AND ARTICLES.STOCK_EN_DEPOT = 'O' THEN '1' ELSE '0' END
|
|
|
FROM prod_sigems.ARTICLES
|
|
|
WHERE CODE_ARTICLE = code_original AND
|
|
|
(
|
|
|
t_articles.gere_en_stock IS DISTINCT FROM CASE WHEN ARTICLES.STOCKABLE = 'O' AND ARTICLES.STOCK_EN_DEPOT <> 'O' THEN '1' ELSE '0' END OR
|
|
|
t_articles.stock_en_depot IS DISTINCT FROM CASE WHEN ARTICLES.STOCKABLE = 'O' AND ARTICLES.STOCK_EN_DEPOT = 'O' THEN '1' ELSE '0' END
|
|
|
)
|
|
|
;
|
|
|
|
|
|
UPDATE eco.t_articles SET
|
|
|
taux_tva_en_cours = TAUX
|
|
|
FROM
|
|
|
(
|
|
|
SELECT ARTICLES.CODE_ARTICLE,
|
|
|
MAX(COALESCE(date(ART_TVA.JUSQUAU),'20991231'::date)) AS date_fin_tva,
|
|
|
(MAX(ARRAY[COALESCE(date(ART_TVA.JUSQUAU),'20991231'::date)::text,COALESCE(TXTVA2.TAUX,TXTVA1.TAUX,20)::text]))[2]::numeric AS TAUX
|
|
|
FROM prod_sigems.ARTICLES
|
|
|
LEFT JOIN prod_sigems.TXTVA TXTVA1 ON TXTVA1.TVA = ARTICLES.CODE_TVA
|
|
|
LEFT JOIN prod_sigems.ART_TVA ON ARTICLES.CODE_ARTICLE = ART_TVA.CODE_ARTICLE AND COALESCE(ART_TVA.JUSQUAU,'20991231') >= date(now())
|
|
|
LEFT JOIN prod_sigems.TXTVA TXTVA2 ON TXTVA2.TVA = ART_TVA.CODE_TVA
|
|
|
GROUP BY 1
|
|
|
) subview
|
|
|
WHERE CODE_ARTICLE = code_original AND
|
|
|
taux_tva_en_cours IS DISTINCT FROM TAUX
|
|
|
;
|
|
|
|
|
|
|
|
|
UPDATE eco.t_articles SET
|
|
|
type_code = t_types_articles.code,
|
|
|
type_texte = t_types_articles.texte_court,
|
|
|
type_section_id = t_types_articles.section_id,
|
|
|
type_section_code = t_types_articles.section_code,
|
|
|
type_section_texte = t_types_articles.section_texte,
|
|
|
|
|
|
famille_code = t_familles_articles.code,
|
|
|
famille_texte = t_familles_articles.texte_court,
|
|
|
famille_section_id = t_familles_articles.section_id,
|
|
|
famille_section_code = t_familles_articles.section_code,
|
|
|
famille_section_texte = t_familles_articles.section_texte,
|
|
|
|
|
|
sous_famille_code = t_sous_familles_articles.code,
|
|
|
sous_famille_texte = t_sous_familles_articles.texte_court,
|
|
|
sous_famille_section_id = t_sous_familles_articles.section_id,
|
|
|
sous_famille_section_code = t_sous_familles_articles.section_code,
|
|
|
sous_famille_section_texte = t_sous_familles_articles.section_texte,
|
|
|
|
|
|
categorie_code = t_categories_articles.code,
|
|
|
categorie_texte = t_categories_articles.texte_court,
|
|
|
categorie_section_id = t_categories_articles.section_id,
|
|
|
categorie_section_code = t_categories_articles.section_code,
|
|
|
categorie_section_texte = t_categories_articles.section_texte,
|
|
|
|
|
|
sous_categorie_code = t_sous_categories_articles.code,
|
|
|
sous_categorie_texte = t_sous_categories_articles.texte_court,
|
|
|
sous_categorie_section_id = t_sous_categories_articles.section_id,
|
|
|
sous_categorie_section_code = t_sous_categories_articles.section_code,
|
|
|
sous_categorie_section_texte = t_sous_categories_articles.section_texte,
|
|
|
|
|
|
classification_atc_code = t_classification_atc.code,
|
|
|
classification_atc_texte = t_classification_atc.texte_court,
|
|
|
classification_atc_section_id = t_classification_atc.section_id,
|
|
|
classification_atc_section_code = t_classification_atc.section_code,
|
|
|
classification_atc_section_texte = t_classification_atc.section_texte,
|
|
|
classification_atc_1_id = t_classification_atc.classification_atc_1_id,
|
|
|
classification_atc_1_code = t_classification_atc.classification_atc_1_code,
|
|
|
classification_atc_1_texte = t_classification_atc.classification_atc_1_texte,
|
|
|
classification_atc_2_id = t_classification_atc.classification_atc_2_id,
|
|
|
classification_atc_2_code = t_classification_atc.classification_atc_2_code,
|
|
|
classification_atc_2_texte = t_classification_atc.classification_atc_2_texte,
|
|
|
classification_atc_3_id = t_classification_atc.classification_atc_3_id,
|
|
|
classification_atc_3_code = t_classification_atc.classification_atc_3_code,
|
|
|
classification_atc_3_texte = t_classification_atc.classification_atc_3_texte,
|
|
|
classification_atc_4_id = t_classification_atc.classification_atc_4_id,
|
|
|
classification_atc_4_code = t_classification_atc.classification_atc_4_code,
|
|
|
classification_atc_4_texte = t_classification_atc.classification_atc_4_texte,
|
|
|
|
|
|
unite_stockage_code = t_unites_stockage.code,
|
|
|
unite_stockage_texte = t_unites_stockage.texte_court,
|
|
|
unite_stockage_section_id = t_unites_stockage.section_id,
|
|
|
unite_stockage_section_code = t_unites_stockage.section_code,
|
|
|
unite_stockage_section_texte = t_unites_stockage.section_texte,
|
|
|
|
|
|
unite_distribution_code = t_unites_distribution.code,
|
|
|
unite_distribution_texte = t_unites_distribution.texte_court,
|
|
|
unite_distribution_section_id = t_unites_distribution.section_id,
|
|
|
unite_distribution_section_code = t_unites_distribution.section_code,
|
|
|
unite_distribution_section_texte = t_unites_distribution.section_texte,
|
|
|
|
|
|
compte_code = t_compte.code,
|
|
|
compte_texte = t_compte.texte_court,
|
|
|
compte_section_id = t_compte.section_id,
|
|
|
compte_section_code = t_compte.section_code,
|
|
|
compte_section_texte = t_compte.section_texte
|
|
|
|
|
|
FROM eco.t_types_articles ,
|
|
|
eco.t_familles_articles,
|
|
|
eco.t_sous_familles_articles,
|
|
|
eco.t_categories_articles,
|
|
|
eco.t_sous_categories_articles,
|
|
|
eco.t_classification_atc,
|
|
|
eco.t_unites t_unites_stockage,
|
|
|
eco.t_unites t_unites_distribution,
|
|
|
eco.t_compte
|
|
|
|
|
|
WHERE type_id = t_types_articles.oid
|
|
|
AND famille_id = t_familles_articles.oid
|
|
|
AND sous_famille_id = t_sous_familles_articles.oid
|
|
|
AND categorie_id = t_categories_articles.oid
|
|
|
AND sous_categorie_id = t_sous_categories_articles.oid
|
|
|
AND classification_atc_id = t_classification_atc.oid
|
|
|
AND unite_stockage_id = t_unites_stockage.oid
|
|
|
AND unite_distribution_id = t_unites_distribution.oid
|
|
|
AND compte_id = t_compte.oid
|
|
|
AND (
|
|
|
type_code IS DISTINCT FROM t_types_articles.code OR
|
|
|
type_texte IS DISTINCT FROM t_types_articles.texte_court OR
|
|
|
type_section_id IS DISTINCT FROM t_types_articles.section_id OR
|
|
|
type_section_code IS DISTINCT FROM t_types_articles.section_code OR
|
|
|
type_section_texte IS DISTINCT FROM t_types_articles.section_texte OR
|
|
|
|
|
|
famille_code IS DISTINCT FROM t_familles_articles.code OR
|
|
|
famille_texte IS DISTINCT FROM t_familles_articles.texte_court OR
|
|
|
famille_section_id IS DISTINCT FROM t_familles_articles.section_id OR
|
|
|
famille_section_code IS DISTINCT FROM t_familles_articles.section_code OR
|
|
|
famille_section_texte IS DISTINCT FROM t_familles_articles.section_texte OR
|
|
|
|
|
|
sous_famille_code IS DISTINCT FROM t_sous_familles_articles.code OR
|
|
|
sous_famille_texte IS DISTINCT FROM t_sous_familles_articles.texte_court OR
|
|
|
sous_famille_section_id IS DISTINCT FROM t_sous_familles_articles.section_id OR
|
|
|
sous_famille_section_code IS DISTINCT FROM t_sous_familles_articles.section_code OR
|
|
|
sous_famille_section_texte IS DISTINCT FROM t_sous_familles_articles.section_texte OR
|
|
|
|
|
|
categorie_code IS DISTINCT FROM t_categories_articles.code OR
|
|
|
categorie_texte IS DISTINCT FROM t_categories_articles.texte_court OR
|
|
|
categorie_section_id IS DISTINCT FROM t_categories_articles.section_id OR
|
|
|
categorie_section_code IS DISTINCT FROM t_categories_articles.section_code OR
|
|
|
categorie_section_texte IS DISTINCT FROM t_categories_articles.section_texte OR
|
|
|
|
|
|
sous_categorie_code IS DISTINCT FROM t_sous_categories_articles.code OR
|
|
|
sous_categorie_texte IS DISTINCT FROM t_sous_categories_articles.texte_court OR
|
|
|
sous_categorie_section_id IS DISTINCT FROM t_sous_categories_articles.section_id OR
|
|
|
sous_categorie_section_code IS DISTINCT FROM t_sous_categories_articles.section_code OR
|
|
|
sous_categorie_section_texte IS DISTINCT FROM t_sous_categories_articles.section_texte OR
|
|
|
|
|
|
t_articles.classification_atc_code IS DISTINCT FROM t_classification_atc.code OR
|
|
|
t_articles.classification_atc_texte IS DISTINCT FROM t_classification_atc.texte_court OR
|
|
|
t_articles.classification_atc_section_id IS DISTINCT FROM t_classification_atc.section_id OR
|
|
|
t_articles.classification_atc_section_code IS DISTINCT FROM t_classification_atc.section_code OR
|
|
|
t_articles.classification_atc_section_texte IS DISTINCT FROM t_classification_atc.section_texte OR
|
|
|
t_articles.classification_atc_1_id IS DISTINCT FROM t_classification_atc.classification_atc_1_id OR
|
|
|
t_articles.classification_atc_1_code IS DISTINCT FROM t_classification_atc.classification_atc_1_code OR
|
|
|
t_articles.classification_atc_1_texte IS DISTINCT FROM t_classification_atc.classification_atc_1_texte OR
|
|
|
t_articles.classification_atc_2_id IS DISTINCT FROM t_classification_atc.classification_atc_2_id OR
|
|
|
t_articles.classification_atc_2_code IS DISTINCT FROM t_classification_atc.classification_atc_2_code OR
|
|
|
t_articles.classification_atc_2_texte IS DISTINCT FROM t_classification_atc.classification_atc_2_texte OR
|
|
|
t_articles.classification_atc_3_id IS DISTINCT FROM t_classification_atc.classification_atc_3_id OR
|
|
|
t_articles.classification_atc_3_code IS DISTINCT FROM t_classification_atc.classification_atc_3_code OR
|
|
|
t_articles.classification_atc_3_texte IS DISTINCT FROM t_classification_atc.classification_atc_3_texte OR
|
|
|
t_articles.classification_atc_4_id IS DISTINCT FROM t_classification_atc.classification_atc_4_id OR
|
|
|
t_articles.classification_atc_4_code IS DISTINCT FROM t_classification_atc.classification_atc_4_code OR
|
|
|
t_articles.classification_atc_4_texte IS DISTINCT FROM t_classification_atc.classification_atc_4_texte OR
|
|
|
|
|
|
t_articles.unite_stockage_code IS DISTINCT FROM t_unites_stockage.code OR
|
|
|
t_articles.unite_stockage_texte IS DISTINCT FROM t_unites_stockage.texte_court OR
|
|
|
t_articles.unite_stockage_section_id IS DISTINCT FROM t_unites_stockage.section_id OR
|
|
|
t_articles.unite_stockage_section_code IS DISTINCT FROM t_unites_stockage.section_code OR
|
|
|
t_articles.unite_stockage_section_texte IS DISTINCT FROM t_unites_stockage.section_texte OR
|
|
|
|
|
|
t_articles.unite_distribution_code IS DISTINCT FROM t_unites_distribution.code OR
|
|
|
t_articles.unite_distribution_texte IS DISTINCT FROM t_unites_distribution.texte_court OR
|
|
|
t_articles.unite_distribution_section_id IS DISTINCT FROM t_unites_distribution.section_id OR
|
|
|
t_articles.unite_distribution_section_code IS DISTINCT FROM t_unites_distribution.section_code OR
|
|
|
t_articles.unite_distribution_section_texte IS DISTINCT FROM t_unites_distribution.section_texte OR
|
|
|
|
|
|
t_articles.compte_code IS DISTINCT FROM t_compte.code OR
|
|
|
t_articles.compte_texte IS DISTINCT FROM t_compte.texte_court OR
|
|
|
t_articles.compte_section_id IS DISTINCT FROM t_compte.section_id OR
|
|
|
t_articles.compte_section_code IS DISTINCT FROM t_compte.section_code OR
|
|
|
t_articles.compte_section_texte IS DISTINCT FROM t_compte.section_texte
|
|
|
);
|
|
|
|
|
|
|
|
|
|
|
|
]]></sqlcmd>
|
|
|
</NODE>
|
|
|
|
|
|
|
|
|
<NODE label="Tables Fournisseurs">
|
|
|
<sqlcmd><![CDATA[
|
|
|
|
|
|
DROP TABLE IF EXISTS w_FOURNISSEUR;
|
|
|
CREATE TEMP TABLE w_FOURNISSEUR AS
|
|
|
SELECT FOURNISSEUR.*,
|
|
|
COALESCE(ADRESSE.RUE,'') AS RUE,
|
|
|
COALESCE(ADRESSE.COMPLEMENT_RUE,'') AS COMPLEMENT_RUE,
|
|
|
COALESCE(ADRESSE.CODE_POSTAL,'') AS CODE_POSTAL,
|
|
|
COALESCE(ADRESSE.BUREAU_DISTRIB,'') AS BUREAU_DISTRIB,
|
|
|
COALESCE(ADRESSE.PAYS,'') AS PAYS,
|
|
|
COALESCE(ADRESSE.TELEPHONE,'') AS TELEPHONE,
|
|
|
COALESCE(ADRESSE.TELECOPIE,'') AS TELECOPIE,
|
|
|
COALESCE(ADRESSE.E_MAIL,'') AS E_MAIL,
|
|
|
COALESCE(ADRESSE.ADRESSE_WEB,'') AS ADRESSE_WEB,
|
|
|
TYPE_FOURNISSEUR::text AS TYPE_FOURNISSEUR_CODE_CTI,
|
|
|
COALESCE(replace(IBAN_CODPAYS||IBAN_CODCONTROLE||IBAN_BBAN,' ',''),'') AS IBAN,
|
|
|
COALESCE(AFFACTURAGE.SIRET,'') AS AFFACTURAGE_SIRET,
|
|
|
trim(COALESCE(BIC_CODBQ||BIC_CODPAYS||BIC_CODEMPL,'')) AS BIC
|
|
|
FROM prod_sigems.FOURNISSEUR
|
|
|
LEFT JOIN prod_sigems.ADRESSE ON CODE_FOURNISSEUR = CODE_ADRESSE
|
|
|
LEFT JOIN (
|
|
|
SELECT
|
|
|
COMPTE,
|
|
|
MAX(IBAN_CODPAYS) AS IBAN_CODPAYS,
|
|
|
MAX(IBAN_CODCONTROLE) AS IBAN_CODCONTROLE,
|
|
|
MAX(IBAN_BBAN) AS IBAN_BBAN,
|
|
|
MAX(SIRET) AS SIRET,
|
|
|
MAX(BIC_CODBQ) AS BIC_CODBQ,
|
|
|
MAX(BIC_CODPAYS) AS BIC_CODPAYS,
|
|
|
MAX(BIC_CODEMPL) AS BIC_CODEMPL
|
|
|
FROM prod_sigems.AFFACTURAGE
|
|
|
WHERE
|
|
|
AFFACTURAGE.TYPS = 'F' AND
|
|
|
AFFACTURAGE.COMPTE <> ''
|
|
|
GROUP BY 1
|
|
|
) AFFACTURAGE ON
|
|
|
AFFACTURAGE.COMPTE = FOURNISSEUR.CODE_COMPTABLE
|
|
|
;
|
|
|
|
|
|
UPDATE w_FOURNISSEUR
|
|
|
SET IBAN = substr(IBAN,1,4) || ' ' || substr(IBAN,5,4) || ' ' || substr(IBAN,9,4) || ' ' || substr(IBAN,13,4) || ' ' || substr(IBAN,17,4) || ' ' || substr(IBAN,21,4) || ' ' || substr(IBAN,25,3)
|
|
|
WHERE IBAN <> ''
|
|
|
;
|
|
|
|
|
|
UPDATE w_FOURNISSEUR
|
|
|
SET SIRET = AFFACTURAGE_SIRET
|
|
|
WHERE AFFACTURAGE_SIRET <> ''
|
|
|
;
|
|
|
|
|
|
|
|
|
-- Types de fournisseurs
|
|
|
DROP TABLE IF EXISTS w_TYPE_FOURNISSEUR;
|
|
|
CREATE TEMP TABLE w_TYPE_FOURNISSEUR AS
|
|
|
SELECT TYPE_FOURNISSEUR.CODE::text,
|
|
|
UPPER(TYPE_FOURNISSEUR.CODE)::text AS CODE_CTI,
|
|
|
TYPE_FOURNISSEUR.GROUPE::text,
|
|
|
TYPE_FOURNISSEUR.CODE::text AS GROUPE_CODE,
|
|
|
UPPER(MAX(TYPE_FOURNISSEUR.LIBELLE))::text AS LIBELLE
|
|
|
FROM prod_sigems.TYPE_FOURNISSEUR
|
|
|
JOIN w_FOURNISSEUR FOURNISSEUR ON
|
|
|
TYPE_FOURNISSEUR.GROUPE = FOURNISSEUR.GROUPE AND
|
|
|
TYPE_FOURNISSEUR.CODE = FOURNISSEUR.TYPE_FOURNISSEUR
|
|
|
WHERE CODE <> ''
|
|
|
GROUP BY 1,2,3
|
|
|
ORDER BY 1,2;
|
|
|
|
|
|
UPDATE w_TYPE_FOURNISSEUR SET
|
|
|
CODE_CTI = CODE_CTI || ' (' || GROUPE || ')',
|
|
|
GROUPE_CODE = CODE || '-' || GROUPE
|
|
|
WHERE CODE IN (SELECT CODE FROM w_TYPE_FOURNISSEUR GROUP BY 1 HAVING COUNT(DISTINCT LIBELLE) > 1);
|
|
|
|
|
|
INSERT INTO eco.t_types_fournisseurs(code, texte, texte_court, code_original)
|
|
|
SELECT CODE_CTI, LIBELLE, LIBELLE, GROUPE_CODE
|
|
|
FROM w_TYPE_FOURNISSEUR
|
|
|
WHERE GROUPE_CODE NOT IN (SELECT code_original FROM eco.t_types_fournisseurs WHERE code_original IS NOT NULL)
|
|
|
GROUP BY 1,2,3,4
|
|
|
ORDER BY 1;
|
|
|
|
|
|
UPDATE w_FOURNISSEUR SET
|
|
|
TYPE_FOURNISSEUR_CODE_CTI = w_TYPE_FOURNISSEUR.CODE_CTI
|
|
|
FROM w_TYPE_FOURNISSEUR
|
|
|
WHERE w_TYPE_FOURNISSEUR.GROUPE = w_FOURNISSEUR.GROUPE AND
|
|
|
w_TYPE_FOURNISSEUR.CODE = w_FOURNISSEUR.TYPE_FOURNISSEUR AND
|
|
|
TYPE_FOURNISSEUR_CODE_CTI IS DISTINCT FROM w_TYPE_FOURNISSEUR.CODE_CTI;
|
|
|
|
|
|
|
|
|
-- Fournisseurs
|
|
|
INSERT INTO eco.t_fournisseurs(code, texte, texte_court, code_original)
|
|
|
SELECT CODE_FOURNISSEUR,
|
|
|
UPPER(NOM_FOURNISSEUR),
|
|
|
UPPER(NOM_FOURNISSEUR),
|
|
|
CODE_FOURNISSEUR
|
|
|
FROM w_FOURNISSEUR FOURNISSEUR
|
|
|
LEFT JOIN eco.t_fournisseurs ON (code_original = CODE_FOURNISSEUR)
|
|
|
WHERE code_original IS NULL
|
|
|
GROUP BY 1,2,3,4;
|
|
|
|
|
|
INSERT INTO base.t_codes_postaux(code, texte, texte_court, departement_id)
|
|
|
SELECT FOURNISSEUR.CODE_POSTAL, UPPER(MAX(FOURNISSEUR.BUREAU_DISTRIB)), UPPER(MAX(FOURNISSEUR.BUREAU_DISTRIB)), MAX(t_departements.oid)
|
|
|
FROM w_FOURNISSEUR FOURNISSEUR
|
|
|
LEFT JOIN base.t_codes_postaux ON FOURNISSEUR.CODE_POSTAL = t_codes_postaux.code
|
|
|
JOIN base.t_departements ON
|
|
|
FOURNISSEUR.CODE_POSTAL NOT LIKE '97%' AND substr(FOURNISSEUR.CODE_POSTAL,1,2) = t_departements.code OR
|
|
|
FOURNISSEUR.CODE_POSTAL LIKE '97%' AND substr(FOURNISSEUR.CODE_POSTAL,1,3) = t_departements.code
|
|
|
WHERE t_codes_postaux.oid IS NULL AND
|
|
|
length(FOURNISSEUR.CODE_POSTAL) = 5
|
|
|
GROUP BY 1
|
|
|
;
|
|
|
|
|
|
UPDATE eco.t_fournisseurs SET
|
|
|
texte = UPPER(NOM_FOURNISSEUR),
|
|
|
texte_court = UPPER(NOM_FOURNISSEUR),
|
|
|
adresse = FOURNISSEUR.RUE || ' ' || FOURNISSEUR.COMPLEMENT_RUE,
|
|
|
code_postal_id = COALESCE(t_codes_postaux.oid,0),
|
|
|
ville = FOURNISSEUR.VILLE_FOURNISSEUR,
|
|
|
cedex = '',
|
|
|
telephone = FOURNISSEUR.TELEPHONE,
|
|
|
fax = FOURNISSEUR.TELECOPIE,
|
|
|
email = FOURNISSEUR.E_MAIL,
|
|
|
siret = FOURNISSEUR.SIRET,
|
|
|
code_cahpp = FORMAT_CODE_BARRE,
|
|
|
iban = FOURNISSEUR.IBAN,
|
|
|
bic = FOURNISSEUR.BIC,
|
|
|
code_comptable = FOURNISSEUR.CODE_COMPTABLE
|
|
|
FROM w_FOURNISSEUR FOURNISSEUR
|
|
|
LEFT JOIN base.t_codes_postaux ON FOURNISSEUR.CODE_POSTAL = t_codes_postaux.code
|
|
|
WHERE code_original = CODE_FOURNISSEUR
|
|
|
AND (
|
|
|
t_fournisseurs.texte IS DISTINCT FROM UPPER(NOM_FOURNISSEUR) OR
|
|
|
t_fournisseurs.texte_court IS DISTINCT FROM UPPER(NOM_FOURNISSEUR) OR
|
|
|
t_fournisseurs.adresse IS DISTINCT FROM (FOURNISSEUR.RUE || ' ' || FOURNISSEUR.COMPLEMENT_RUE) OR
|
|
|
t_fournisseurs.code_postal_id IS DISTINCT FROM COALESCE(t_codes_postaux.oid,0) OR
|
|
|
t_fournisseurs.ville IS DISTINCT FROM FOURNISSEUR.VILLE_FOURNISSEUR OR
|
|
|
t_fournisseurs.cedex IS DISTINCT FROM '' OR
|
|
|
t_fournisseurs.telephone IS DISTINCT FROM FOURNISSEUR.TELEPHONE OR
|
|
|
t_fournisseurs.fax IS DISTINCT FROM FOURNISSEUR.TELECOPIE OR
|
|
|
t_fournisseurs.email IS DISTINCT FROM FOURNISSEUR.E_MAIL OR
|
|
|
t_fournisseurs.siret IS DISTINCT FROM FOURNISSEUR.SIRET OR
|
|
|
t_fournisseurs.code_cahpp IS DISTINCT FROM FORMAT_CODE_BARRE OR
|
|
|
t_fournisseurs.iban IS DISTINCT FROM FOURNISSEUR.IBAN OR
|
|
|
t_fournisseurs.bic IS DISTINCT FROM FOURNISSEUR.BIC OR
|
|
|
t_fournisseurs.code_comptable IS DISTINCT FROM FOURNISSEUR.CODE_COMPTABLE
|
|
|
)
|
|
|
;
|
|
|
|
|
|
UPDATE eco.t_fournisseurs
|
|
|
SET fournisseur_distributeur_id = COALESCE(t_fournisseurs_distributeur.oid, t_fournisseurs.oid)
|
|
|
FROM w_FOURNISSEUR FOURNISSEUR
|
|
|
LEFT JOIN eco.t_fournisseurs t_fournisseurs_distributeur ON
|
|
|
FOURNISSEUR.DISTRIBUTEUR = t_fournisseurs_distributeur.code_original AND
|
|
|
FOURNISSEUR.DISTRIBUTEUR <> '' AND
|
|
|
FOURNISSEUR.DISTRIBUTEUR <> 'LUI'
|
|
|
WHERE t_fournisseurs.code_original = FOURNISSEUR.CODE_FOURNISSEUR AND
|
|
|
t_fournisseurs.fournisseur_distributeur_id IS DISTINCT FROM COALESCE(t_fournisseurs_distributeur.oid, t_fournisseurs.oid)
|
|
|
;
|
|
|
|
|
|
UPDATE eco.t_fournisseurs SET
|
|
|
type_id = COALESCE(t_types_fournisseurs.oid,0)
|
|
|
FROM w_FOURNISSEUR FOURNISSEUR
|
|
|
LEFT JOIN eco.t_types_fournisseurs ON TYPE_FOURNISSEUR_CODE_CTI = t_types_fournisseurs.code_original
|
|
|
WHERE t_fournisseurs.code_original = CODE_FOURNISSEUR AND
|
|
|
type_id IS DISTINCT FROM COALESCE(t_types_fournisseurs.oid,0);
|
|
|
|
|
|
|
|
|
UPDATE eco.t_fournisseurs SET
|
|
|
type_code = t_types_fournisseurs.code,
|
|
|
type_texte = t_types_fournisseurs.texte_court,
|
|
|
type_section_id = t_types_fournisseurs.section_id,
|
|
|
type_section_code = t_types_fournisseurs.section_code,
|
|
|
type_section_texte = t_types_fournisseurs.section_texte
|
|
|
FROM eco.t_types_fournisseurs
|
|
|
WHERE type_id = t_types_fournisseurs.oid
|
|
|
AND (
|
|
|
type_code IS DISTINCT FROM t_types_fournisseurs.code OR
|
|
|
type_texte IS DISTINCT FROM t_types_fournisseurs.texte_court OR
|
|
|
type_section_id IS DISTINCT FROM t_types_fournisseurs.section_id OR
|
|
|
type_section_code IS DISTINCT FROM t_types_fournisseurs.section_code OR
|
|
|
type_section_texte IS DISTINCT FROM t_types_fournisseurs.section_texte
|
|
|
);
|
|
|
|
|
|
|
|
|
|
|
|
DROP TABLE IF EXISTS w_ARTICLES_FOURNISSEUR;
|
|
|
CREATE TEMP TABLE w_ARTICLES_FOURNISSEUR AS
|
|
|
SELECT
|
|
|
ARTICLE_PRIXACHA.CODE_ARTICLE,
|
|
|
ARTICLE_PRIXACHA.CODE_FOURNISSEUR,
|
|
|
MAX(ARTICLE_PRIXACHA.PRINCIPAL) AS PRINCIPAL,
|
|
|
MAX(ARTICLES.UCD) AS UCD,
|
|
|
''::text AS UCD13,
|
|
|
MAX(ARTICLES.CODE_TIPS) AS CODE_TIPS,
|
|
|
(MAX(ARRAY[ARTICLE_PRIXACHA.A_COMPTER_DU::text,CODE_CHEZ_FOURNIS::text]))[2]::text AS CODE_CHEZ_FOURNIS,
|
|
|
(MAX(ARRAY[ARTICLE_PRIXACHA.A_COMPTER_DU::text,LIB_CHEZ_FOURNIS::text]))[2]::text AS LIB_CHEZ_FOURNIS,
|
|
|
MAX(CASE WHEN length(ARTICLE_PRIXACHA.LIB_CHEZ_FOURNIS) <= 2 THEN ARTICLE_PRIXACHA.CODE_CHEZ_FOURNIS ELSE ARTICLE_PRIXACHA.LIB_CHEZ_FOURNIS || CASE WHEN ARTICLE_PRIXACHA.CODE_CHEZ_FOURNIS <> '' THEN ' (' || ARTICLE_PRIXACHA.CODE_CHEZ_FOURNIS || ')' ELSE '' END END) AS LIB_CODE_CHEZ_FOURNIS,
|
|
|
(MAX(ARRAY[ARTICLE_PRIXACHA.A_COMPTER_DU::text,E_PRIX::text]))[2]::numeric AS E_PX_UNIT_NET,
|
|
|
(MAX(ARRAY[ARTICLE_PRIXACHA.A_COMPTER_DU::text,CASE WHEN ARTICLE_PRIXACHA.COEFF_ACHAT <> 0 THEN ARTICLE_PRIXACHA.COEFF_ACHAT ELSE ARTICLE_PRIXACHA.COEFF_CONSO END::text]))[2]::numeric AS COEFF_UNITE,
|
|
|
MAX(ARTICLE_PRIXACHA.A_COMPTER_DU) AS A_COMPTER_DU,
|
|
|
(MAX(ARRAY[ARTICLE_PRIXACHA.A_COMPTER_DU::text,UNITE_ACHAT::text]))[2]::text AS UNITE_ACHAT,
|
|
|
(MAX(ARRAY[ARTICLE_PRIXACHA.A_COMPTER_DU::text,CIP::text]))[2]::text AS CIP,
|
|
|
count(*) AS nb,
|
|
|
0::bigint AS article_id,
|
|
|
0::bigint AS fournisseur_id,
|
|
|
0::bigint AS fournisseur_distributeur_id
|
|
|
FROM prod_sigems.ARTICLE_PRIXACHA
|
|
|
JOIN prod_sigems.ARTICLES ON ARTICLES.CODE_ARTICLE = ARTICLE_PRIXACHA.CODE_ARTICLE
|
|
|
GROUP BY 1,2
|
|
|
ORDER BY 1;
|
|
|
|
|
|
|
|
|
DROP TABLE IF EXISTS w_ARTICLES_FOURNISSEURA;
|
|
|
CREATE TEMP TABLE w_ARTICLES_FOURNISSEURA AS
|
|
|
SELECT
|
|
|
ACHA_LIGNE.CODE_ARTICLE,
|
|
|
ACHA_ENTETE.CODE_FOURNISSEUR,
|
|
|
'N'::text AS PRINCIPAL,
|
|
|
MAX(ARTICLES.UCD) AS UCD,
|
|
|
''::text AS UCD13,
|
|
|
MAX(ARTICLES.CODE_TIPS) AS CODE_TIPS,
|
|
|
(MAX(ARRAY[ACHA_ENTETE.DATE_COMMANDE::text,ACHA_LIGNE.CODE_CHEZ_FOURNIS::text]))[2]::text AS CODE_CHEZ_FOURNIS,
|
|
|
(MAX(ARRAY[ACHA_ENTETE.DATE_COMMANDE::text,ACHA_LIGNE.LIB_CHEZ_FOURNIS::text]))[2]::text AS LIB_CHEZ_FOURNIS,
|
|
|
MAX(CASE WHEN length(ACHA_LIGNE.LIB_CHEZ_FOURNIS) <= 2 THEN ACHA_LIGNE.CODE_CHEZ_FOURNIS ELSE ACHA_LIGNE.LIB_CHEZ_FOURNIS || CASE WHEN ACHA_LIGNE.CODE_CHEZ_FOURNIS <> '' THEN ' (' || ACHA_LIGNE.CODE_CHEZ_FOURNIS || ')' ELSE '' END END) AS LIB_CODE_CHEZ_FOURNIS,
|
|
|
(MAX(ARRAY[ACHA_ENTETE.DATE_COMMANDE::text,ACHA_LIGNE.E_PX_UNIT_NET::text]))[2]::numeric AS E_PX_UNIT_NET,
|
|
|
(MAX(ARRAY[ACHA_ENTETE.DATE_COMMANDE::text,ACHA_LIGNE.COEFF_UNITE::text]))[2]::numeric AS COEFF_UNITE,
|
|
|
MAX(ACHA_ENTETE.DATE_COMMANDE) AS A_COMPTER_DU,
|
|
|
(MAX(ARRAY[ACHA_ENTETE.DATE_COMMANDE::text,ACHA_LIGNE.UNITE_ACHAT::text]))[2]::text AS UNITE_ACHAT,
|
|
|
(MAX(ARRAY[ACHA_ENTETE.DATE_COMMANDE::text,CODE_BARRE::text]))[2]::text AS CIP,
|
|
|
count(*) AS nb,
|
|
|
0::bigint AS article_id,
|
|
|
0::bigint AS fournisseur_id,
|
|
|
0::bigint AS fournisseur_distributeur_id
|
|
|
FROM prod_sigems.ACHA_LIGNE
|
|
|
JOIN prod_sigems.ACHA_ENTETE ON ACHA_LIGNE.NUMERO_CDE = ACHA_ENTETE.NUMERO_CDE
|
|
|
JOIN prod_sigems.ARTICLES ON ARTICLES.CODE_ARTICLE = ACHA_LIGNE.CODE_ARTICLE
|
|
|
GROUP BY 1,2
|
|
|
ORDER BY 1,2
|
|
|
;
|
|
|
INSERT INTO w_ARTICLES_FOURNISSEUR
|
|
|
SELECT
|
|
|
w_ARTICLES_FOURNISSEURA.*
|
|
|
FROM w_ARTICLES_FOURNISSEURA
|
|
|
LEFT JOIN w_ARTICLES_FOURNISSEUR ON
|
|
|
w_ARTICLES_FOURNISSEUR.CODE_ARTICLE = w_ARTICLES_FOURNISSEURA.CODE_ARTICLE AND
|
|
|
w_ARTICLES_FOURNISSEUR.CODE_FOURNISSEUR = w_ARTICLES_FOURNISSEURA.CODE_FOURNISSEUR
|
|
|
WHERE w_ARTICLES_FOURNISSEUR.CODE_ARTICLE IS NULL
|
|
|
;
|
|
|
|
|
|
UPDATE w_ARTICLES_FOURNISSEUR
|
|
|
SET PRINCIPAL = 'N'
|
|
|
FROM
|
|
|
(
|
|
|
SELECT CODE_ARTICLE, (MAX(ARRAY[A_COMPTER_DU::text,CODE_FOURNISSEUR::text]))[2] AS CODE_FOURNISSEUR
|
|
|
FROM w_ARTICLES_FOURNISSEUR
|
|
|
WHERE PRINCIPAL = 'O'
|
|
|
GROUP BY 1
|
|
|
HAVING count(*) > 1
|
|
|
) subview
|
|
|
WHERE w_ARTICLES_FOURNISSEUR.CODE_ARTICLE = subview.CODE_ARTICLE AND
|
|
|
w_ARTICLES_FOURNISSEUR.PRINCIPAL = 'O' AND
|
|
|
w_ARTICLES_FOURNISSEUR.CODE_FOURNISSEUR <> subview.CODE_FOURNISSEUR
|
|
|
;
|
|
|
|
|
|
UPDATE w_ARTICLES_FOURNISSEUR SET
|
|
|
COEFF_UNITE = w_ARTICLES_FOURNISSEURA.COEFF_UNITE
|
|
|
FROM w_ARTICLES_FOURNISSEURA
|
|
|
WHERE w_ARTICLES_FOURNISSEUR.CODE_ARTICLE = w_ARTICLES_FOURNISSEURA.CODE_ARTICLE AND
|
|
|
w_ARTICLES_FOURNISSEUR.CODE_FOURNISSEUR = w_ARTICLES_FOURNISSEURA.CODE_FOURNISSEUR AND
|
|
|
w_ARTICLES_FOURNISSEUR.COEFF_UNITE IS DISTINCT FROM w_ARTICLES_FOURNISSEURA.COEFF_UNITE
|
|
|
;
|
|
|
|
|
|
UPDATE w_ARTICLES_FOURNISSEUR
|
|
|
SET UCD13 = CODE_CHEZ_FOURNIS
|
|
|
WHERE length(CODE_CHEZ_FOURNIS) = 13 AND
|
|
|
CODE_CHEZ_FOURNIS LIKE '34008%'
|
|
|
;
|
|
|
|
|
|
UPDATE w_ARTICLES_FOURNISSEUR
|
|
|
SET UCD13 = CIP
|
|
|
WHERE length(CIP) = 13 AND
|
|
|
CIP LIKE '34008%' AND ucd = ''
|
|
|
;
|
|
|
|
|
|
UPDATE w_ARTICLES_FOURNISSEUR
|
|
|
SET article_id = t_articles.oid
|
|
|
FROM eco.t_articles
|
|
|
WHERE CODE_ARTICLE = t_articles.code
|
|
|
;
|
|
|
|
|
|
UPDATE w_ARTICLES_FOURNISSEUR SET
|
|
|
UCD13 = UCD,
|
|
|
UCD = substr(UCD,6,7)
|
|
|
WHERE length(UCD) = 13 AND
|
|
|
UCD LIKE '34008%'
|
|
|
;
|
|
|
|
|
|
UPDATE w_ARTICLES_FOURNISSEUR
|
|
|
SET UCD = substr(UCD13,6,7)
|
|
|
WHERE UCD = '' AND UCD13 <> ''
|
|
|
;
|
|
|
|
|
|
UPDATE w_ARTICLES_FOURNISSEUR SET
|
|
|
fournisseur_id = t_fournisseurs.oid,
|
|
|
fournisseur_distributeur_id = t_fournisseurs.fournisseur_distributeur_id
|
|
|
FROM eco.t_fournisseurs
|
|
|
WHERE CODE_FOURNISSEUR = t_fournisseurs.code
|
|
|
;
|
|
|
|
|
|
UPDATE eco.t_articles SET
|
|
|
ref_fournisseur_id = subview.ref_fournisseur_id,
|
|
|
ref_fournisseur_code = subview.ref_fournisseur_code,
|
|
|
ref_fournisseur_texte = subview.ref_fournisseur_texte
|
|
|
FROM
|
|
|
(
|
|
|
SELECT article_id,
|
|
|
base.cti_group_array3(fournisseur_id) AS ref_fournisseur_id,
|
|
|
base.cti_group_array3(ref_fournisseur_code) AS ref_fournisseur_code,
|
|
|
base.cti_group_array3(ref_fournisseur_texte) AS ref_fournisseur_texte
|
|
|
FROM
|
|
|
(
|
|
|
SELECT
|
|
|
article_id,
|
|
|
fournisseur_id,
|
|
|
(MAX(Array[A_COMPTER_DU::text, CASE WHEN CODE_CHEZ_FOURNIS <> '' THEN CODE_CHEZ_FOURNIS WHEN UCD <> '' THEN UCD WHEN CODE_TIPS <> '' THEN CODE_TIPS ELSE LIB_CHEZ_FOURNIS END]))[2] AS ref_fournisseur_code,
|
|
|
(MAX(Array[A_COMPTER_DU::text, LIB_CODE_CHEZ_FOURNIS]))[2] AS ref_fournisseur_texte
|
|
|
FROM w_ARTICLES_FOURNISSEUR
|
|
|
GROUP BY 1,2
|
|
|
ORDER BY 1,2
|
|
|
) subview
|
|
|
GROUP BY 1
|
|
|
) subview
|
|
|
WHERE t_articles.oid = subview.article_id AND
|
|
|
(
|
|
|
t_articles.ref_fournisseur_id IS DISTINCT FROM subview.ref_fournisseur_id OR
|
|
|
t_articles.ref_fournisseur_code IS DISTINCT FROM subview.ref_fournisseur_code OR
|
|
|
t_articles.ref_fournisseur_texte IS DIStINCT FROM subview.ref_fournisseur_texte
|
|
|
)
|
|
|
;
|
|
|
|
|
|
DROP TABLE IF EXISTS w_articles_fournisseur_eco;
|
|
|
CREATE TEMP TABLE w_articles_fournisseur_eco AS
|
|
|
SELECT
|
|
|
CODE_ARTICLE||'|'||CODE_FOURNISSEUR AS code_original,
|
|
|
MAX(article_id) AS article_id,
|
|
|
MAX(fournisseur_id) AS fournisseur_id,
|
|
|
MAX(fournisseur_distributeur_id) AS fournisseur_distributeur_id,
|
|
|
MAX(CASE WHEN PRINCIPAL = 'O' THEN '1' ELSE '0' END) AS est_fournisseur_principal,
|
|
|
(MAX(Array[A_COMPTER_DU::text, CASE WHEN CODE_CHEZ_FOURNIS <> '' THEN CODE_CHEZ_FOURNIS WHEN UCD <> '' THEN UCD WHEN CODE_TIPS <> '' THEN CODE_TIPS ELSE LIB_CHEZ_FOURNIS END]))[2] AS code_reference_fournisseur,
|
|
|
(MAX(Array[A_COMPTER_DU::text, LIB_CHEZ_FOURNIS]))[2] AS texte_reference_fournisseur,
|
|
|
MAX(CIP) AS code_cip,
|
|
|
''::text AS code_cahpp,
|
|
|
MAX(COALESCE(t_unites.oid,0)) AS unite_approvisionnement_id,
|
|
|
MAX(COEFF_UNITE) AS nombre_conditionnement_approvisionnement,
|
|
|
(MAX(Array[A_COMPTER_DU::text, E_PX_UNIT_NET::text]))[2]::numeric AS prix_unitaire_en_cours,
|
|
|
MAX(COALESCE(t_ucd.oid,0)) AS ucd_id,
|
|
|
MAX(UCD13) AS code_ucd13
|
|
|
FROM w_ARTICLES_FOURNISSEUR
|
|
|
LEFT JOIN eco.t_unites ON UNITE_ACHAT = t_unites.code_original
|
|
|
LEFT JOIN base.t_ucd ON w_ARTICLES_FOURNISSEUR.ucd = t_ucd.code
|
|
|
GROUP BY 1
|
|
|
;
|
|
|
|
|
|
INSERT INTO eco.t_article_fournisseur (
|
|
|
code_original,
|
|
|
article_id,
|
|
|
fournisseur_id,
|
|
|
fournisseur_distributeur_id,
|
|
|
est_fournisseur_principal,
|
|
|
code_reference_fournisseur,
|
|
|
texte_reference_fournisseur,
|
|
|
code_cip,
|
|
|
code_cahpp,
|
|
|
unite_approvisionnement_id,
|
|
|
nombre_conditionnement_approvisionnement,
|
|
|
prix_unitaire_en_cours,
|
|
|
ucd_id,
|
|
|
code_ucd13
|
|
|
)
|
|
|
SELECT
|
|
|
code_original,
|
|
|
article_id,
|
|
|
fournisseur_id,
|
|
|
fournisseur_distributeur_id,
|
|
|
est_fournisseur_principal,
|
|
|
code_reference_fournisseur,
|
|
|
texte_reference_fournisseur,
|
|
|
code_cip,
|
|
|
code_cahpp,
|
|
|
unite_approvisionnement_id,
|
|
|
nombre_conditionnement_approvisionnement,
|
|
|
prix_unitaire_en_cours,
|
|
|
ucd_id,
|
|
|
code_ucd13
|
|
|
FROM w_articles_fournisseur_eco
|
|
|
WHERE w_articles_fournisseur_eco.code_original NOT IN (SELECT t_article_fournisseur.code_original FROM eco.t_article_fournisseur WHERE code_original IS NOT NULL)
|
|
|
;
|
|
|
|
|
|
UPDATE eco.t_article_fournisseur SET
|
|
|
article_id = w_articles_fournisseur_eco.article_id,
|
|
|
fournisseur_id = w_articles_fournisseur_eco.fournisseur_id,
|
|
|
fournisseur_distributeur_id = w_articles_fournisseur_eco.fournisseur_distributeur_id,
|
|
|
est_fournisseur_principal = w_articles_fournisseur_eco.est_fournisseur_principal,
|
|
|
code_reference_fournisseur = w_articles_fournisseur_eco.code_reference_fournisseur,
|
|
|
texte_reference_fournisseur = w_articles_fournisseur_eco.texte_reference_fournisseur,
|
|
|
code_cip = w_articles_fournisseur_eco.code_cip,
|
|
|
code_cahpp = w_articles_fournisseur_eco.code_cahpp,
|
|
|
unite_approvisionnement_id = w_articles_fournisseur_eco.unite_approvisionnement_id,
|
|
|
nombre_conditionnement_approvisionnement = w_articles_fournisseur_eco.nombre_conditionnement_approvisionnement,
|
|
|
prix_unitaire_en_cours = w_articles_fournisseur_eco.prix_unitaire_en_cours,
|
|
|
ucd_id = w_articles_fournisseur_eco.ucd_id,
|
|
|
code_ucd13 = w_articles_fournisseur_eco.code_ucd13
|
|
|
FROM w_articles_fournisseur_eco
|
|
|
WHERE t_article_fournisseur.code_original = w_articles_fournisseur_eco.code_original AND
|
|
|
(
|
|
|
t_article_fournisseur.article_id IS DISTINCT FROM w_articles_fournisseur_eco.article_id OR
|
|
|
t_article_fournisseur.fournisseur_id IS DISTINCT FROM w_articles_fournisseur_eco.fournisseur_id OR
|
|
|
t_article_fournisseur.fournisseur_distributeur_id IS DISTINCT FROM w_articles_fournisseur_eco.fournisseur_distributeur_id OR
|
|
|
t_article_fournisseur.est_fournisseur_principal IS DISTINCT FROM w_articles_fournisseur_eco.est_fournisseur_principal OR
|
|
|
t_article_fournisseur.code_reference_fournisseur IS DISTINCT FROM w_articles_fournisseur_eco.code_reference_fournisseur OR
|
|
|
t_article_fournisseur.texte_reference_fournisseur IS DISTINCT FROM w_articles_fournisseur_eco.texte_reference_fournisseur OR
|
|
|
t_article_fournisseur.code_cip IS DISTINCT FROM w_articles_fournisseur_eco.code_cip OR
|
|
|
t_article_fournisseur.code_cahpp IS DISTINCT FROM w_articles_fournisseur_eco.code_cahpp OR
|
|
|
t_article_fournisseur.unite_approvisionnement_id IS DISTINCT FROM w_articles_fournisseur_eco.unite_approvisionnement_id OR
|
|
|
t_article_fournisseur.nombre_conditionnement_approvisionnement IS DISTINCT FROM w_articles_fournisseur_eco.nombre_conditionnement_approvisionnement OR
|
|
|
t_article_fournisseur.prix_unitaire_en_cours IS DISTINCT FROM w_articles_fournisseur_eco.prix_unitaire_en_cours OR
|
|
|
t_article_fournisseur.ucd_id IS DISTINCT FROM w_articles_fournisseur_eco.ucd_id OR
|
|
|
t_article_fournisseur.code_ucd13 IS DISTINCT FROM w_articles_fournisseur_eco.code_ucd13
|
|
|
)
|
|
|
;
|
|
|
|
|
|
|
|
|
|
|
|
]]></sqlcmd>
|
|
|
</NODE>
|
|
|
|
|
|
|
|
|
|
|
|
<NODE label="Autres tables">
|
|
|
<sqlcmd><![CDATA[
|
|
|
|
|
|
-- Lieux
|
|
|
|
|
|
-- Livraison
|
|
|
INSERT INTO eco.t_lieux(code, code_original, texte, texte_court)
|
|
|
SELECT
|
|
|
UPPER(
|
|
|
substr(split_part(LIEU_LIVRAISON,' ',1),1,3) ||
|
|
|
substr(split_part(LIEU_LIVRAISON,' ',2),1,3) ||
|
|
|
substr(split_part(LIEU_LIVRAISON,' ',3),1,3) ||
|
|
|
substr(split_part(LIEU_LIVRAISON,' ',4),1,3)
|
|
|
),
|
|
|
upper(LIEU_LIVRAISON),
|
|
|
MAX(LIEU_LIVRAISON),
|
|
|
MAX(LIEU_LIVRAISON)
|
|
|
FROM prod_sigems.ACHA_ENTETE
|
|
|
WHERE LIEU_LIVRAISON <> '' AND
|
|
|
upper(LIEU_LIVRAISON) NOT IN (SELECT code_original FROM eco.t_lieux)
|
|
|
GROUP BY 1,2;
|
|
|
|
|
|
-- Stock
|
|
|
INSERT INTO eco.t_lieux(code, code_original, texte, texte_court)
|
|
|
SELECT
|
|
|
CODE_STOCK,
|
|
|
CODE_STOCK,
|
|
|
MAX(CODE_STOCK),
|
|
|
MAX(CODE_STOCK)
|
|
|
FROM prod_sigems.MVT_STOCK
|
|
|
WHERE CODE_STOCK <> '' AND
|
|
|
CODE_STOCK NOT IN (SELECT code_original FROM eco.t_lieux)
|
|
|
GROUP BY 1,2;
|
|
|
|
|
|
INSERT INTO eco.t_lieux(code, code_original, texte, texte_court)
|
|
|
SELECT
|
|
|
CODE_STOCK,
|
|
|
CODE_STOCK,
|
|
|
MAX(CODE_STOCK),
|
|
|
MAX(CODE_STOCK)
|
|
|
FROM prod_sigems.STOCK
|
|
|
WHERE CODE_STOCK <> '' AND
|
|
|
CODE_STOCK NOT IN (SELECT code_original FROM eco.t_lieux)
|
|
|
GROUP BY 1,2;
|
|
|
|
|
|
-- Gestionnaires
|
|
|
INSERT INTO eco.t_gestionnaires(code_original, code, texte, texte_court)
|
|
|
SELECT GROUPE.CODE, GROUPE.CODE, GROUPE.NOM, GROUPE.NOM
|
|
|
FROM prod_sigems.GROUPE
|
|
|
LEFT JOIN eco.t_gestionnaires ON code_original = GROUPE.CODE
|
|
|
WHERE code_original IS NULL
|
|
|
;
|
|
|
|
|
|
-- Unités fonctionnelles
|
|
|
|
|
|
INSERT INTO eco.t_unites_fonctionnelles(code, texte, texte_court, code_original)
|
|
|
SELECT SERVICE_DEST,SERVICE_DEST,SERVICE_DEST,SERVICE_DEST
|
|
|
FROM prod_sigems.MVT_STOCK
|
|
|
LEFT JOIN eco.t_unites_fonctionnelles ON code_original = SERVICE_DEST
|
|
|
WHERE SERVICE_DEST <> '' AND
|
|
|
code_original IS NULL
|
|
|
GROUP BY 1
|
|
|
ORDER BY 1;
|
|
|
|
|
|
UPDATE eco.t_unites_fonctionnelles
|
|
|
SET texte = nom, texte_court = nom
|
|
|
FROM prod_sigems.SERVIC
|
|
|
WHERE SERVIC.code = t_unites_fonctionnelles.code_original
|
|
|
;
|
|
|
|
|
|
-- Unités
|
|
|
|
|
|
INSERT INTO eco.t_unites(code, texte, texte_court, code_original)
|
|
|
SELECT UNITE_MVT,UNITE_MVT,UNITE_MVT,UNITE_MVT
|
|
|
FROM prod_sigems.MVT_STOCK
|
|
|
LEFT JOIN eco.t_unites ON code_original = UNITE_MVT
|
|
|
WHERE UNITE_MVT IS NOT NULL AND
|
|
|
code_original IS NULL
|
|
|
GROUP BY 1
|
|
|
ORDER BY 1;
|
|
|
|
|
|
INSERT INTO eco.t_unites(code, texte, texte_court, code_original)
|
|
|
SELECT UNITE_ACHAT,UNITE_ACHAT,UNITE_ACHAT,UNITE_ACHAT
|
|
|
FROM prod_sigems.ACHA_LIGNE
|
|
|
LEFT JOIN eco.t_unites ON code_original = UNITE_ACHAT
|
|
|
WHERE UNITE_ACHAT IS NOT NULL AND
|
|
|
code_original IS NULL
|
|
|
GROUP BY 1
|
|
|
ORDER BY 1;
|
|
|
|
|
|
-- Site
|
|
|
|
|
|
|
|
|
|
|
|
-- Types mouvements
|
|
|
|
|
|
INSERT INTO eco.t_types_mouvements(code, code_original, texte, texte_court)
|
|
|
SELECT NATURE_MVT_STOCK.CODE, NATURE_MVT_STOCK.CODE, MAX(LIBELLE), MAX(LIBELLE)
|
|
|
FROM prod_sigems.NATURE_MVT_STOCK
|
|
|
LEFT JOIN eco.t_types_mouvements ON code_original = NATURE_MVT_STOCK.CODE
|
|
|
WHERE NATURE_MVT_STOCK.CODE <> '' AND t_types_mouvements.oid IS NULL
|
|
|
GROUP BY 1,2;
|
|
|
|
|
|
|
|
|
|
|
|
]]></sqlcmd>
|
|
|
</NODE>
|
|
|
|
|
|
|
|
|
</NODE>
|
|
|
<NODE name="PROD" label="RECUPERATION DES DONNEES DE PRODUCTION">
|
|
|
|
|
|
<NODE label="Préparation">
|
|
|
<sqlcmd><![CDATA[
|
|
|
|
|
|
-- TVA articles
|
|
|
DROP SEQUENCE IF EXISTS w_ARTICLES_TVA_sequence;
|
|
|
CREATE TEMP SEQUENCE w_ARTICLES_TVA_sequence;
|
|
|
|
|
|
DROP TABLE IF EXISTS w_ARTICLES_TVA;
|
|
|
CREATE TEMP TABLE w_ARTICLES_TVA AS
|
|
|
SELECT subview.*, nextval(' w_ARTICLES_TVA_sequence'::regclass) AS sequence
|
|
|
FROM
|
|
|
(
|
|
|
SELECT ARTICLES.CODE_ARTICLE, '00010101'::date AS date_debut_tva, '20991231'::date AS date_fin_tva, 1+(COALESCE(TXTVA.TAUX,20)/100) AS taux_tva
|
|
|
FROM prod_sigems.ARTICLES
|
|
|
LEFT JOIN prod_sigems.TXTVA ON TXTVA.TVA = ARTICLES.CODE_TVA
|
|
|
UNION
|
|
|
|
|
|
SELECT ARTICLES.CODE_ARTICLE, '00010101'::date AS date_debut_tva, date(ART_TVA.JUSQUAU) AS date_fin_tva, 1+(COALESCE(TXTVA.TAUX,20)/100) AS taux_tva
|
|
|
FROM prod_sigems.ARTICLES
|
|
|
JOIN prod_sigems.ART_TVA ON ARTICLES.CODE_ARTICLE = ART_TVA.CODE_ARTICLE
|
|
|
JOIN prod_sigems.TXTVA ON TXTVA.TVA = ART_TVA.CODE_TVA
|
|
|
|
|
|
ORDER BY 1,3
|
|
|
) subview;
|
|
|
|
|
|
CREATE INDEX w_ARTICLES_TVA_i1 ON w_ARTICLES_TVA USING btree (CODE_ARTICLE);
|
|
|
|
|
|
|
|
|
UPDATE w_ARTICLES_TVA
|
|
|
SET date_debut_tva = w_ARTICLES_TVA2.date_fin_tva + interval '1 day'
|
|
|
FROM w_ARTICLES_TVA w_ARTICLES_TVA2
|
|
|
WHERE w_ARTICLES_TVA2.CODE_ARTICLE = w_ARTICLES_TVA.CODE_ARTICLE AND
|
|
|
w_ARTICLES_TVA2.sequence = w_ARTICLES_TVA.sequence-1;
|
|
|
|
|
|
]]></sqlcmd>
|
|
|
</NODE>
|
|
|
|
|
|
<NODE label="Préparation des tables">
|
|
|
<sqlcmd><![CDATA[
|
|
|
|
|
|
DROP TABLE IF EXISTS w_ACHA_LIGNE;
|
|
|
CREATE TEMP TABLE w_ACHA_LIGNE AS
|
|
|
SELECT
|
|
|
|
|
|
QUANTITE_LIVREE + CASE WHEN RELIQUAT_ANNULE <> 'O' THEN QUANTITE_RESTE ELSE 0 END AS C_QUANTITE_COMMANDEE,
|
|
|
|
|
|
|
|
|
CASE WHEN QUANTITE_RESTE = 0 OR RELIQUAT_ANNULE = 'O' THEN 'T' ELSE 'N' END AS etat_livraison,
|
|
|
(QUANTITE_LIVREE + CASE WHEN RELIQUAT_ANNULE <> 'O' THEN QUANTITE_RESTE ELSE 0 END) * E_PX_UNIT_NET AS C_MONTANT_HT,
|
|
|
((QUANTITE_LIVREE + CASE WHEN RELIQUAT_ANNULE <> 'O' THEN QUANTITE_RESTE ELSE 0 END) * E_PX_UNIT_NET) * TAUX_TVA / 100 AS C_MONTANT_TVA,
|
|
|
(QUANTITE_LIVREE) * E_PX_UNIT_NET AS C_MONTANT_LIVRE_HT,
|
|
|
((QUANTITE_LIVREE) * E_PX_UNIT_NET) * TAUX_TVA / 100 AS C_MONTANT_LIVRE_TVA,
|
|
|
|
|
|
CASE WHEN DATE_FACT IS NOT NULL THEN 'T' ELSE 'N' END AS etat_liquidation,
|
|
|
CASE WHEN DATE_FACT IS NOT NULL THEN QUANTITE_LIVREE * E_PX_UNIT_NET ELSE 0 END AS C_MONTANT_LIQUIDE_HT,
|
|
|
CASE WHEN DATE_FACT IS NOT NULL THEN (QUANTITE_LIVREE * E_PX_UNIT_NET) * TAUX_TVA / 100 ELSE 0 END AS C_MONTANT_LIQUIDE_TVA,
|
|
|
|
|
|
ACHA_LIGNE.*,
|
|
|
ACHA_ENTETE.TYPE_CDE,
|
|
|
CASE WHEN
|
|
|
cume_dist() OVER (PARTITION BY ACHA_LIGNE.NUMERO_CDE, NUMERO_LIGNE ORDER BY ACHA_LIGNE.DATE_CREATION, REF_UNIQUE_MVT) != 1 OR
|
|
|
row_number() OVER (PARTITION BY ACHA_LIGNE.NUMERO_CDE, NUMERO_LIGNE ORDER BY ACHA_LIGNE.DATE_CREATION, CODE_ARTICLE, REF_UNIQUE_MVT) != 1
|
|
|
THEN (NUMERO_LIGNE || '.' || row_number() OVER (PARTITION BY ACHA_LIGNE.NUMERO_CDE, NUMERO_LIGNE ORDER BY ACHA_LIGNE.DATE_CREATION, REF_UNIQUE_MVT))::numeric
|
|
|
ELSE NUMERO_LIGNE END AS NUMERO_LIGNE_CORR
|
|
|
FROM prod_sigems.ACHA_LIGNE
|
|
|
JOIN prod_sigems.ACHA_ENTETE ON ACHA_LIGNE.NUMERO_CDE = ACHA_ENTETE.NUMERO_CDE
|
|
|
WHERE RELIQUAT_ANNULE <> 'O' OR QUANTITE_LIVREE <> 0 OR QUANTITE_RESTE <> 0
|
|
|
;
|
|
|
|
|
|
ANALYSE w_ACHA_LIGNE
|
|
|
;
|
|
|
|
|
|
DROP TABLE IF EXISTS w_MVT_STOCK;
|
|
|
CREATE TEMP TABLE w_MVT_STOCK AS
|
|
|
SELECT MVT_STOCK.*,
|
|
|
CODE_MVT::text AS code_original,
|
|
|
0::bigint AS commande_id,
|
|
|
0::bigint AS gestionnaire_id
|
|
|
FROM prod_sigems.MVT_STOCK
|
|
|
JOIN eco.t_lieux ON CODE_STOCK = t_lieux.code_original AND t_lieux.est_ignore IS DISTINCT FROM '1'
|
|
|
WHERE DATE_MVT BETWEEN '[ENV_ECO_ANNEEDEBUT]0101' AND date(now())
|
|
|
;
|
|
|
|
|
|
ANALYSE w_MVT_STOCK
|
|
|
;
|
|
|
|
|
|
UPDATE w_MVT_STOCK
|
|
|
SET gestionnaire_id = t_gestionnaires.oid
|
|
|
FROM prod_sigems.ARTICLES
|
|
|
JOIN eco.t_gestionnaires ON ARTICLES.GROUPE = t_gestionnaires.code_original
|
|
|
WHERE w_MVT_STOCK.CODE_ARTICLE = ARTICLES.CODE_ARTICLE
|
|
|
;
|
|
|
|
|
|
|
|
|
|
|
|
]]></sqlcmd>
|
|
|
</NODE>
|
|
|
|
|
|
<NODE label="Traitement des réappros">
|
|
|
<condition><![CDATA[
|
|
|
|
|
|
SELECT count(*) > 0
|
|
|
FROM eco.t_divers
|
|
|
WHERE code = 'SIGEMS_SAP_REAPPRO' AND
|
|
|
valeur = '1'
|
|
|
;
|
|
|
]]></condition>
|
|
|
<sqlcmd><![CDATA[
|
|
|
-- Pour les réappros, il y a deux commandes dans SIGEMS, une pour les entrées et une pour les sorties (demande de facturation,
|
|
|
-- il faut fusionner en gardant la seconde
|
|
|
-- Les tables de travail sont ensuite utilisées pour les insert
|
|
|
INSERT INTO eco.t_divers (code, texte, valeur, description)
|
|
|
SELECT
|
|
|
'SIGEMS_SAP_REAPPRO'::text,
|
|
|
'Traitement réappro SIGEMS pour SAP'::text,
|
|
|
'0'::text,
|
|
|
'0=Non, 1=Oui'::text
|
|
|
WHERE 'SIGEMS_SAP_REAPPRO'::text NOT IN (SELECT code FROM eco.t_divers)
|
|
|
;
|
|
|
|
|
|
DROP TABLE IF EXISTS w_ACHA_LIGNE_INI1;
|
|
|
CREATE TEMP TABLE w_ACHA_LIGNE_INI1 AS
|
|
|
SELECT NUMERO_CDE, NUMERO_LIGNE
|
|
|
FROM prod_sigems.ACHA_LIGNE
|
|
|
WHERE NUMERO_CDE_INI <> 0
|
|
|
GROUP BY 1,2
|
|
|
;
|
|
|
|
|
|
ANALYSE w_ACHA_LIGNE_INI1
|
|
|
;
|
|
|
|
|
|
DROP TABLE IF EXISTS w_ACHA_LIGNE_INI2;
|
|
|
CREATE TEMP TABLE w_ACHA_LIGNE_INI2 AS
|
|
|
SELECT NUMERO_CDE_INI,
|
|
|
NUMERO_LIGNE_INI,
|
|
|
ACHA_LIGNE.NUMERO_CDE,
|
|
|
ACHA_LIGNE.NUMERO_LIGNE,
|
|
|
MAX(w_MVT_STOCK.CODE_STOCK) AS MVT_STOCK_CODE_STOCK,
|
|
|
MAX(w_MVT_STOCK.LIBELLE) AS MVT_STOCK_LIBELLE,
|
|
|
MAX(w_MVT_STOCK.NATURE_MVT) AS MVT_STOCK_NATURE_MVT
|
|
|
|
|
|
FROM prod_sigems.ACHA_LIGNE
|
|
|
JOIN w_MVT_STOCK ON
|
|
|
w_MVT_STOCK.NUMERO_CDE = NUMERO_CDE_INI AND
|
|
|
w_MVT_STOCK.NUMERO_LIGNE = NUMERO_LIGNE_INI
|
|
|
WHERE NUMERO_CDE_INI <> 0
|
|
|
GROUP BY 1,2,3,4
|
|
|
ORDER BY 1,2,3,4
|
|
|
;
|
|
|
|
|
|
ANALYSE w_ACHA_LIGNE_INI2
|
|
|
;
|
|
|
|
|
|
|
|
|
DROP TABLE IF EXISTS w_MVT_STOCK_DMI_in;
|
|
|
CREATE TEMP TABLE w_MVT_STOCK_DMI_in AS
|
|
|
SELECT w_MVT_STOCK.*,
|
|
|
MVT_STOCK_CODE_STOCK,
|
|
|
MVT_STOCK_LIBELLE,
|
|
|
MVT_STOCK_NATURE_MVT
|
|
|
FROM w_MVT_STOCK
|
|
|
JOIN w_ACHA_LIGNE_INI1 ON
|
|
|
w_MVT_STOCK.NUMERO_CDE = w_ACHA_LIGNE_INI1.NUMERO_CDE AND
|
|
|
w_MVT_STOCK.NUMERO_LIGNE = w_ACHA_LIGNE_INI1.NUMERO_LIGNE
|
|
|
JOIN w_ACHA_LIGNE_INI2 ON
|
|
|
w_MVT_STOCK.NUMERO_CDE = w_ACHA_LIGNE_INI2.NUMERO_CDE AND
|
|
|
w_MVT_STOCK.NUMERO_LIGNE = w_ACHA_LIGNE_INI2.NUMERO_LIGNE
|
|
|
;
|
|
|
|
|
|
UPDATE w_MVT_STOCK_DMI_in SET
|
|
|
LIBELLE = MVT_STOCK_LIBELLE,
|
|
|
NATURE_MVT = MVT_STOCK_NATURE_MVT,
|
|
|
PLUS_MOINS = 0-PLUS_MOINS,
|
|
|
code_original = code_original || 'E'
|
|
|
;
|
|
|
|
|
|
ALTER TABLE w_MVT_STOCK_DMI_in DROP COLUMN MVT_STOCK_CODE_STOCK;
|
|
|
ALTER TABLE w_MVT_STOCK_DMI_in DROP COLUMN MVT_STOCK_LIBELLE;
|
|
|
ALTER TABLE w_MVT_STOCK_DMI_in DROP COLUMN MVT_STOCK_NATURE_MVT;
|
|
|
|
|
|
INSERT INTO w_MVT_STOCK
|
|
|
SELECT * FROM w_MVT_STOCK_DMI_in
|
|
|
;
|
|
|
|
|
|
DELETE FROM w_MVT_STOCK
|
|
|
USING w_ACHA_LIGNE_INI2
|
|
|
WHERE
|
|
|
w_MVT_STOCK.NUMERO_CDE = w_ACHA_LIGNE_INI2.NUMERO_CDE_INI AND
|
|
|
w_MVT_STOCK.NUMERO_LIGNE = w_ACHA_LIGNE_INI2.NUMERO_LIGNE_INI
|
|
|
;
|
|
|
|
|
|
DELETE FROM w_ACHA_LIGNE
|
|
|
USING w_ACHA_LIGNE_INI2
|
|
|
WHERE
|
|
|
w_ACHA_LIGNE.NUMERO_CDE = w_ACHA_LIGNE_INI2.NUMERO_CDE_INI AND
|
|
|
w_ACHA_LIGNE.NUMERO_LIGNE = w_ACHA_LIGNE_INI2.NUMERO_LIGNE_INI
|
|
|
;
|
|
|
|
|
|
DROP TABLE IF EXISTS w_LIVRAISON_DMI_in;
|
|
|
CREATE TEMP TABLE w_LIVRAISON_DMI_in AS
|
|
|
SELECT NUMERO_CDE, NUMERO_LIGNE,
|
|
|
SUM(PLUS_MOINS * quantite) AS QUANTITE_LIVREE_DMI_in
|
|
|
FROM w_MVT_STOCK_DMI_in
|
|
|
GROUP BY 1,2
|
|
|
;
|
|
|
|
|
|
ANALYSE w_LIVRAISON_DMI_in
|
|
|
;
|
|
|
|
|
|
UPDATE w_ACHA_LIGNE SET
|
|
|
QUANTITE_RESTE = QUANTITE_RESTE - QUANTITE_LIVREE_DMI_in,
|
|
|
QUANTITE_LIVREE = QUANTITE_LIVREE + QUANTITE_LIVREE_DMI_in,
|
|
|
C_MONTANT_LIVRE_HT = (QUANTITE_LIVREE+QUANTITE_LIVREE_DMI_in) * E_PX_UNIT_NET,
|
|
|
C_MONTANT_LIVRE_TVA = ((QUANTITE_LIVREE+QUANTITE_LIVREE_DMI_in) * E_PX_UNIT_NET) * TAUX_TVA / 100,
|
|
|
C_MONTANT_LIQUIDE_HT = CASE WHEN DATE_FACT IS NOT NULL THEN (QUANTITE_LIVREE+QUANTITE_LIVREE_DMI_in) * E_PX_UNIT_NET ELSE 0 END,
|
|
|
C_MONTANT_LIQUIDE_TVA = CASE WHEN DATE_FACT IS NOT NULL THEN ((QUANTITE_LIVREE+QUANTITE_LIVREE_DMI_in) * E_PX_UNIT_NET) * TAUX_TVA / 100 ELSE 0 END
|
|
|
FROM w_LIVRAISON_DMI_IN
|
|
|
WHERE w_ACHA_LIGNE.NUMERO_CDE = w_LIVRAISON_DMI_in.NUMERO_CDE AND
|
|
|
w_ACHA_LIGNE.NUMERO_LIGNE = w_LIVRAISON_DMI_in.NUMERO_LIGNE
|
|
|
;
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
]]></sqlcmd>
|
|
|
</NODE>
|
|
|
|
|
|
|
|
|
<NODE label="Commandes">
|
|
|
<sqlcmd><![CDATA[
|
|
|
|
|
|
|
|
|
SELECT base.cti_disable_index('eco', 'i_commandes_1');
|
|
|
SELECT base.cti_disable_index('eco', 'i_commandes_2');
|
|
|
SELECT base.cti_disable_index('eco', 'i_commandes_3');
|
|
|
SELECT base.cti_disable_index('eco', 'i_commandes_4');
|
|
|
SELECT base.cti_disable_index('eco', 'i_commandes_5');
|
|
|
SELECT base.cti_disable_index('eco', 'i_commandes_6');
|
|
|
SELECT base.cti_disable_index('eco', 'i_commandes_7');
|
|
|
SELECT base.cti_disable_index('eco', 'i_commandes_8');
|
|
|
|
|
|
|
|
|
|
|
|
TRUNCATE eco.p_commandes;
|
|
|
|
|
|
INSERT INTO eco.p_commandes(
|
|
|
code_original,
|
|
|
numero,
|
|
|
date_commande,
|
|
|
date_engagement,
|
|
|
objet,
|
|
|
reference,
|
|
|
date_livraison_prevue,
|
|
|
etat_reception,
|
|
|
date_reception,
|
|
|
etat_liquidation,
|
|
|
fournisseur_id,
|
|
|
fournisseur_distributeur_id,
|
|
|
gestionnaire_id,
|
|
|
lieu_commande_id,
|
|
|
lieu_facturation_id,
|
|
|
lieu_livraison_id,
|
|
|
unite_fonctionnelle_id,
|
|
|
montant_commande_ht,
|
|
|
montant_commande_remise,
|
|
|
montant_commande_tva,
|
|
|
montant_commande_port,
|
|
|
montant_commande_total,
|
|
|
montant_liquidation_ht,
|
|
|
montant_liquidation_remise,
|
|
|
montant_liquidation_tva,
|
|
|
montant_liquidation_port,
|
|
|
montant_liquidation_total)
|
|
|
SELECT
|
|
|
ACHA_ENTETE.NUMERO_CDE AS code_original,
|
|
|
ACHA_ENTETE.NUMERO_DATE AS numero,
|
|
|
date(MAX(ACHA_ENTETE.DATE_COMMANDE)) AS date_commande,
|
|
|
date(MAX(ACHA_ENTETE.DATE_COMMANDE)) AS date_commande,
|
|
|
''::text AS objet,
|
|
|
''::text AS reference,
|
|
|
'20991231'::date AS date_livraison_prevue,
|
|
|
CASE
|
|
|
WHEN MIN(etat_livraison) = 'T' AND MAX(etat_livraison) = 'T' THEN 'T'
|
|
|
WHEN MAX(etat_livraison) = 'N' THEN 'N'
|
|
|
ELSE 'P' END AS etat_reception,
|
|
|
'20991231'::date AS date_reception,
|
|
|
CASE
|
|
|
WHEN MIN(etat_liquidation) = 'T' AND MAX(etat_liquidation) = 'T' THEN 'T'
|
|
|
WHEN MAX(etat_liquidation) = 'N' THEN 'N'
|
|
|
ELSE 'P' END AS etat_liquidation,
|
|
|
MAX(COALESCE(t_fournisseurs.oid, 0)) AS fournisseur_id,
|
|
|
MAX(COALESCE(t_fournisseurs.fournisseur_distributeur_id, 0)) AS fournisseur_distributeur_id,
|
|
|
MAX(COALESCE(t_gestionnaires.oid,0)) AS gestionnaire_id,
|
|
|
0::bigint AS lieu_commande_id,
|
|
|
0::bigint AS lieu_facturation_id,
|
|
|
MAX(COALESCE(t_lieux_livraison.oid, 0)) AS lieu_livraison_id,
|
|
|
0::bigint AS unite_fonctionnelle_id,
|
|
|
SUM(C_MONTANT_HT) AS montant_commande_ht,
|
|
|
0::numeric AS montant_commande_remise,
|
|
|
SUM(C_MONTANT_TVA) AS montant_commande_tva,
|
|
|
0::numeric AS montant_commande_port,
|
|
|
SUM(C_MONTANT_HT+C_MONTANT_TVA) AS montant_commande_total,
|
|
|
SUM(C_MONTANT_LIQUIDE_HT) AS montant_liquidation_ht,
|
|
|
0::numeric AS montant_liquidation_remise,
|
|
|
SUM(C_MONTANT_LIQUIDE_TVA) AS montant_liquidation_tva,
|
|
|
0::numeric AS montant_liquidation_port,
|
|
|
SUM(C_MONTANT_LIQUIDE_HT+C_MONTANT_LIQUIDE_TVA) AS montant_liquidation_total
|
|
|
FROM prod_sigems.ACHA_ENTETE
|
|
|
JOIN w_ACHA_LIGNE ON w_ACHA_LIGNE.NUMERO_CDE = ACHA_ENTETE.NUMERO_CDE
|
|
|
LEFT JOIN eco.t_fournisseurs ON t_fournisseurs.code_original = CODE_FOURNISSEUR
|
|
|
LEFT JOIN eco.t_lieux t_lieux_livraison ON t_lieux_livraison.code_original = upper(LIEU_LIVRAISON) AND LIEU_LIVRAISON <> ''
|
|
|
LEFT JOIN eco.t_gestionnaires ON ACHA_ENTETE.GROUPE = t_gestionnaires.code_original
|
|
|
WHERE ACHA_ENTETE.DATE_COMMANDE >= '[ENV_ECO_ANNEEDEBUT]-01-01'
|
|
|
GROUP BY 1,2
|
|
|
ORDER BY 1;
|
|
|
|
|
|
|
|
|
SELECT base.cti_enable_index('eco', 'i_commandes_1');
|
|
|
SELECT base.cti_enable_index('eco', 'i_commandes_2');
|
|
|
SELECT base.cti_enable_index('eco', 'i_commandes_3');
|
|
|
SELECT base.cti_enable_index('eco', 'i_commandes_4');
|
|
|
SELECT base.cti_enable_index('eco', 'i_commandes_5');
|
|
|
SELECT base.cti_enable_index('eco', 'i_commandes_6');
|
|
|
SELECT base.cti_enable_index('eco', 'i_commandes_7');
|
|
|
SELECT base.cti_enable_index('eco', 'i_commandes_8');
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
SELECT base.cti_disable_index('eco', 'i_ligne_commandes_1');
|
|
|
SELECT base.cti_disable_index('eco', 'i_ligne_commandes_2');
|
|
|
SELECT base.cti_disable_index('eco', 'i_ligne_commandes_3');
|
|
|
|
|
|
TRUNCATE eco.p_lignes_commandes;
|
|
|
|
|
|
INSERT INTO eco.p_lignes_commandes(
|
|
|
code_original,
|
|
|
commande_id,
|
|
|
ligne_commande,
|
|
|
texte,
|
|
|
fournisseur_distributeur_id,
|
|
|
article_id,
|
|
|
unite_approvisionnement_id,
|
|
|
compte_id,
|
|
|
ucd_id,
|
|
|
lpp_id,
|
|
|
|
|
|
quantite_approvisionnement,
|
|
|
prix_unitaire_approvisionnement,
|
|
|
multiplicateur_stockage,
|
|
|
quantite_stockage,
|
|
|
prix_unitaire_stockage,
|
|
|
|
|
|
montant_commande_ht,
|
|
|
montant_commande_remise,
|
|
|
montant_commande_tva,
|
|
|
montant_commande_port,
|
|
|
montant_commande_ttc,
|
|
|
|
|
|
quantite_livraison_approvisionnement,
|
|
|
quantite_livraison_stockage,
|
|
|
montant_livraison_ht,
|
|
|
montant_livraison_ttc,
|
|
|
etat_livraison,
|
|
|
|
|
|
montant_liquidation_ht,
|
|
|
montant_liquidation_remise,
|
|
|
montant_liquidation_tva,
|
|
|
montant_liquidation_port,
|
|
|
montant_liquidation_ttc,
|
|
|
etat_liquidation,
|
|
|
|
|
|
taux_prorata_tva,
|
|
|
taux_tva)
|
|
|
SELECT
|
|
|
p_commandes.code_original || '-' || NUMERO_LIGNE_CORR AS code_original,
|
|
|
p_commandes.oid AS commande_id,
|
|
|
NUMERO_LIGNE_CORR AS ligne_commande,
|
|
|
REF_LOT AS texte,
|
|
|
p_commandes.fournisseur_distributeur_id,
|
|
|
COALESCE(t_articles.oid, 0) AS article_id,
|
|
|
COALESCE(t_unites.oid,0) AS unite_approvisionnement_id,
|
|
|
COALESCE(t_compte.oid, t_articles.compte_id, 0) AS compte_id,
|
|
|
COALESCE(t_ucd.oid, t_articles.ucd_id, 0) AS ucd_id,
|
|
|
COALESCE(t_lpp.oid, t_articles.lpp_id, 0) AS lpp_id,
|
|
|
|
|
|
QUANTITE_COMMANDEE AS quantite_approvisionnement,
|
|
|
E_PX_UNIT_NET AS prix_unitaire_approvisionnement,
|
|
|
0::numeric AS multiplicateur_stockage,
|
|
|
0::numeric AS quantite_stockage,
|
|
|
0::numeric AS prix_unitaire_stockage,
|
|
|
|
|
|
E_PX_UNIT_NET * QUANTITE_COMMANDEE AS montant_commande_ht,
|
|
|
0::numeric AS montant_commande_remise,
|
|
|
C_MONTANT_TVA AS montant_commande_tva,
|
|
|
0::numeric AS montant_commande_port,
|
|
|
E_PX_UNIT_NET * QUANTITE_COMMANDEE + C_MONTANT_TVA AS montant_commande_ttc,
|
|
|
|
|
|
QUANTITE_LIVREE AS quantite_livraison_approvisionnement,
|
|
|
QUANTITE_LIVREE AS quantite_livraison_stockage,
|
|
|
C_MONTANT_LIVRE_HT AS montant_livraison_ht,
|
|
|
C_MONTANT_LIVRE_HT + C_MONTANT_LIVRE_TVA AS montant_livraison_ttc,
|
|
|
w_ACHA_LIGNE.etat_livraison,
|
|
|
|
|
|
C_MONTANT_LIQUIDE_HT AS montant_liquidation_ht,
|
|
|
0::numeric AS montant_liquidation_remise,
|
|
|
C_MONTANT_LIQUIDE_TVA AS montant_liquidation_tva,
|
|
|
0::numeric AS montant_liquidation_port,
|
|
|
C_MONTANT_LIQUIDE_HT + C_MONTANT_LIQUIDE_TVA AS montant_liquidation_ttc,
|
|
|
w_ACHA_LIGNE.etat_liquidation,
|
|
|
|
|
|
CASE WHEN t_articles.type_prorata_tva IS DISTINCT FROM '1' AND t_compte.type_prorata_tva IS DISTINCT FROM '1' THEN COALESCE(t_prorata_tva.taux,0) ELSE 0 END,
|
|
|
w_ACHA_LIGNE.TAUX_TVA
|
|
|
FROM w_ACHA_LIGNE
|
|
|
JOIN eco.p_commandes ON NUMERO_CDE = p_commandes.code_original
|
|
|
LEFT JOIN eco.t_articles ON w_ACHA_LIGNE.CODE_ARTICLE = t_articles.code_original AND t_articles.oid <> 0
|
|
|
LEFT JOIN eco.t_compte ON 'x' = t_compte.code_original AND t_compte.oid <> 0
|
|
|
LEFT JOIN eco.t_unites ON UNITE_ACHAT = t_unites.code_original
|
|
|
LEFT JOIN base.t_ucd ON 'x' = t_ucd.code AND t_ucd.oid <> 0
|
|
|
LEFT JOIN base.t_lpp ON 'x' = t_lpp.code AND t_lpp.oid <> 0
|
|
|
LEFT JOIN eco.t_prorata_tva ON p_commandes.date_engagement BETWEEN t_prorata_tva.date_debut AND t_prorata_tva.date_fin
|
|
|
;
|
|
|
|
|
|
|
|
|
SELECT base.cti_enable_index('eco', 'i_ligne_commandes_1');
|
|
|
SELECT base.cti_enable_index('eco', 'i_ligne_commandes_2');
|
|
|
SELECT base.cti_enable_index('eco', 'i_ligne_commandes_3');
|
|
|
|
|
|
]]></sqlcmd>
|
|
|
</NODE>
|
|
|
|
|
|
<NODE label="Stocks">
|
|
|
<sqlcmd><![CDATA[
|
|
|
|
|
|
-- Prix distri historisé
|
|
|
DROP SEQUENCE IF EXISTS w_prix_distri_seq;
|
|
|
CREATE TEMP SEQUENCE w_prix_distri_seq;
|
|
|
|
|
|
DROP TABLE IF EXISTS w_prix_distri;
|
|
|
CREATE TEMP TABLE w_prix_distri AS
|
|
|
SELECT subview.*, '20991231'::date AS date_fin, nextval('w_prix_distri_seq'::regclass) AS prix_sequence
|
|
|
FROM
|
|
|
(
|
|
|
SELECT CODE_ARTICLE, date(date_trunc('month',DATE_MVT)) AS date_debut,
|
|
|
(MAX(ARRAY[CODE_MVT::numeric,E_PX_UNIT_NET]))[2] AS prix_distri_ht,
|
|
|
MAX(DATE_MVT)::text AS date_mvt_last,
|
|
|
(MIN(ARRAY[CODE_MVT::numeric,E_PX_UNIT_NET]))[2] AS prix_distri_ht_first,
|
|
|
MAX(CODE_MVT::numeric) AS code_mvt
|
|
|
FROM prod_sigems.MVT_STOCK
|
|
|
WHERE PLUS_MOINS < 0
|
|
|
GROUP BY 1,2
|
|
|
ORDER BY 1,2
|
|
|
) subview;
|
|
|
|
|
|
|
|
|
UPDATE w_prix_distri
|
|
|
SET date_fin = w_prix_distri_next.date_debut - interval '1 day'
|
|
|
FROM w_prix_distri w_prix_distri_next
|
|
|
WHERE w_prix_distri.CODE_ARTICLE = w_prix_distri_next.CODE_ARTICLE AND
|
|
|
w_prix_distri.prix_sequence = w_prix_distri_next.prix_sequence - 1
|
|
|
;
|
|
|
|
|
|
UPDATE w_prix_distri
|
|
|
SET date_debut = date_deb_corr
|
|
|
FROM
|
|
|
(
|
|
|
SELECT w_prix_distri.CODE_ARTICLE, w_prix_distri.date_fin, COALESCE(w_prix_distri_prev.date_fin + interval '1 day', '1900-01-01') as date_deb_corr
|
|
|
FROM w_prix_distri
|
|
|
LEFT JOIN w_prix_distri w_prix_distri_prev
|
|
|
ON w_prix_distri.CODE_ARTICLE = w_prix_distri_prev.CODE_ARTICLE AND
|
|
|
w_prix_distri.prix_sequence = w_prix_distri_prev.prix_sequence + 1
|
|
|
) sub
|
|
|
WHERE sub.CODE_ARTICLE = w_prix_distri.CODE_ARTICLE
|
|
|
AND sub.date_fin = w_prix_distri.date_fin
|
|
|
;
|
|
|
|
|
|
-- maj prix si entrée après dernière sortie sur le mois (dans ce cas le prix de distri est déjà celui du prochain mouvement de sortie)
|
|
|
UPDATE w_prix_distri
|
|
|
SET prix_distri_ht = w_prix_distri_next.prix_distri_ht_first
|
|
|
FROM
|
|
|
(
|
|
|
SELECT CODE_ARTICLE, DATE_MVT
|
|
|
FROM prod_sigems.MVT_STOCK WHERE PLUS_MOINS > 0
|
|
|
) sub,
|
|
|
w_prix_distri w_prix_distri_next
|
|
|
WHERE w_prix_distri.CODE_ARTICLE = sub.CODE_ARTICLE
|
|
|
AND sub.date_mvt BETWEEN w_prix_distri.date_mvt_last AND w_prix_distri.date_fin
|
|
|
AND w_prix_distri_next.CODE_ARTICLE = w_prix_distri.CODE_ARTICLE
|
|
|
AND w_prix_distri_next.prix_sequence = w_prix_distri.prix_sequence + 1
|
|
|
;
|
|
|
|
|
|
|
|
|
-- maj prix si inventaire
|
|
|
UPDATE w_prix_distri SET
|
|
|
prix_distri_ht = E_PX_UNIT_NET::numeric,
|
|
|
date_mvt_last = DATE_MVT
|
|
|
FROM prod_sigems.MVT_STOCK
|
|
|
WHERE w_prix_distri.CODE_ARTICLE = mvt_stock.CODE_ARTICLE
|
|
|
AND date_mvt BETWEEN date_mvt_last AND w_prix_distri.date_fin
|
|
|
AND module = 'I'
|
|
|
;
|
|
|
|
|
|
-- maj prix si entrée après dernière sortie sur le mois
|
|
|
UPDATE w_prix_distri
|
|
|
SET prix_distri_ht = w_prix_distri_next.prix_distri_ht_first
|
|
|
FROM
|
|
|
(
|
|
|
SELECT CODE_ARTICLE, DATE_MVT
|
|
|
FROM prod_sigems.MVT_STOCK
|
|
|
WHERE PLUS_MOINS > 0
|
|
|
) sub,
|
|
|
w_prix_distri w_prix_distri_next
|
|
|
WHERE w_prix_distri.CODE_ARTICLE = sub.CODE_ARTICLE
|
|
|
AND sub.date_mvt BETWEEN w_prix_distri.date_mvt_last AND w_prix_distri.date_fin
|
|
|
AND w_prix_distri_next.CODE_ARTICLE = w_prix_distri.CODE_ARTICLE
|
|
|
AND w_prix_distri_next.prix_sequence = w_prix_distri.prix_sequence + 1
|
|
|
;
|
|
|
|
|
|
-- Prix distri historisé à partir des entrées si pas de sorties
|
|
|
INSERT INTO w_prix_distri
|
|
|
SELECT subview.*, '20991231'::date AS date_fin, nextval('w_prix_distri_seq'::regclass) AS prix_sequence
|
|
|
FROM
|
|
|
(
|
|
|
SELECT CODE_ARTICLE, date(date_trunc('month',DATE_MVT)) AS date_debut,
|
|
|
(MAX(ARRAY[CODE_MVT::numeric,E_PX_UNIT_NET]))[2] AS prix_distri_ht,
|
|
|
(MAX(ARRAY[CODE_MVT::text,DATE_MVT::text]))[2] AS date_mvt_last,
|
|
|
0,
|
|
|
0
|
|
|
FROM prod_sigems.MVT_STOCK
|
|
|
WHERE PLUS_MOINS > 0
|
|
|
AND CODE_ARTICLE not in (select code_article from w_prix_distri)
|
|
|
GROUP BY 1,2
|
|
|
ORDER BY 1,2
|
|
|
) subview;
|
|
|
|
|
|
UPDATE w_prix_distri
|
|
|
SET date_fin = w_prix_distri_next.date_debut - interval '1 day'
|
|
|
FROM w_prix_distri w_prix_distri_next
|
|
|
WHERE w_prix_distri.CODE_ARTICLE = w_prix_distri_next.CODE_ARTICLE AND
|
|
|
w_prix_distri.prix_sequence = w_prix_distri_next.prix_sequence - 1
|
|
|
;
|
|
|
|
|
|
UPDATE w_prix_distri
|
|
|
SET date_debut = date_deb_corr
|
|
|
FROM
|
|
|
(
|
|
|
SELECT w_prix_distri.CODE_ARTICLE, w_prix_distri.date_fin, COALESCE(w_prix_distri_prev.date_fin + interval '1 day', '1900-01-01') as date_deb_corr
|
|
|
FROM w_prix_distri
|
|
|
LEFT JOIN w_prix_distri w_prix_distri_prev
|
|
|
ON w_prix_distri.CODE_ARTICLE = w_prix_distri_prev.CODE_ARTICLE AND
|
|
|
w_prix_distri.prix_sequence = w_prix_distri_prev.prix_sequence + 1
|
|
|
) sub
|
|
|
WHERE sub.CODE_ARTICLE = w_prix_distri.CODE_ARTICLE
|
|
|
AND sub.date_fin = w_prix_distri.date_fin
|
|
|
;
|
|
|
|
|
|
CREATE INDEX w_prix_distri_i1 ON w_prix_distri USING btree (CODE_ARTICLE)
|
|
|
;
|
|
|
|
|
|
|
|
|
DROP TABLE IF EXISTS w_STOCK;
|
|
|
CREATE TEMP TABLE w_STOCK AS
|
|
|
SELECT
|
|
|
CODE_STOCK,
|
|
|
MVT_STOCK.CODE_ARTICLE,
|
|
|
date_part('year',DATE_MVT) * 12 + date_part('month',DATE_MVT) AS mois_sequence,
|
|
|
MIN(date(date_trunc('month',DATE_MVT))) AS date_debut,
|
|
|
date(MAX(date(date_trunc('month',DATE_MVT))) + interval '1 month' - interval '1 day') AS date_fin,
|
|
|
0::numeric AS stock_quantite_debut,
|
|
|
0::numeric AS stock_valeur_debut,
|
|
|
SUM(CASE WHEN PLUS_MOINS > 0 THEN QUANTITE ELSE 0 END) AS entree_quantite,
|
|
|
round(SUM(CASE WHEN PLUS_MOINS > 0 THEN QUANTITE*E_PX_UNIT_NET ELSE 0 END),2) AS entree_montant,
|
|
|
SUM(CASE WHEN PLUS_MOINS > 0 AND QUANTITE > 0 AND E_PX_UNIT_NET <> 0 THEN QUANTITE ELSE 0 END) AS entree_quantite_pump,
|
|
|
round(SUM(CASE WHEN PLUS_MOINS > 0 AND QUANTITE > 0 AND E_PX_UNIT_NET <> 0 THEN QUANTITE*E_PX_UNIT_NET ELSE 0 END),2) AS entree_montant_pump,
|
|
|
SUM(CASE WHEN PLUS_MOINS < 0 THEN QUANTITE ELSE 0 END) AS sortie_quantite,
|
|
|
SUM(CASE
|
|
|
WHEN PLUS_MOINS < 0 AND E_PX_UNIT_NET <> 0 THEN QUANTITE*E_PX_UNIT_NET
|
|
|
WHEN PLUS_MOINS < 0 AND E_PX_UNIT_NET = 0 THEN QUANTITE*COALESCE(prix_distri_ht)
|
|
|
ELSE 0 END
|
|
|
) AS sortie_montant,
|
|
|
SUM(CASE WHEN PLUS_MOINS < 0 AND E_PX_UNIT_NET <> 0 THEN QUANTITE ELSE 0 END) AS sortie_quantite_valorise,
|
|
|
SUM(CASE WHEN PLUS_MOINS < 0 AND E_PX_UNIT_NET <> 0 THEN QUANTITE*E_PX_UNIT_NET ELSE 0 END) AS sortie_montant_valorise,
|
|
|
SUM(CASE WHEN PLUS_MOINS < 0 AND E_PX_UNIT_NET = 0 THEN QUANTITE ELSE 0 END) AS sortie_quantite_non_valorise,
|
|
|
SUM(CASE WHEN PLUS_MOINS < 0 AND E_PX_UNIT_NET = 0 THEN QUANTITE*E_PX_UNIT_NET ELSE 0 END) AS sortie_montant_non_valorise,
|
|
|
0::numeric AS stock_quantite_fin,
|
|
|
0::numeric AS stock_valeur_fin,
|
|
|
0::numeric AS pump,
|
|
|
'0'::text AS ok_stock_fin
|
|
|
FROM prod_sigems.MVT_STOCK
|
|
|
JOIN eco.t_lieux ON CODE_STOCK = t_lieux.code_original AND t_lieux.est_ignore IS DISTINCT FROM '1'
|
|
|
LEFT JOIN w_prix_distri ON
|
|
|
MVT_STOCK.CODE_ARTICLE = w_prix_distri.CODE_ARTICLE AND
|
|
|
MVT_STOCK.DATE_MVT BETWEEN w_prix_distri.date_debut AND w_prix_distri.date_fin
|
|
|
WHERE DATE_MVT BETWEEN '[ENV_ECO_ANNEEDEBUT]-01-01' AND date(now()) OR
|
|
|
(DATE_MVT BETWEEN '[ENV_ECO_ANNEEDEBUT]-01-01' AND date(now()) AND PLUS_MOINS > 0 AND QUANTITE > 0 AND E_PX_UNIT_NET <> 0)
|
|
|
GROUP BY 1,2,3
|
|
|
HAVING SUM(PLUS_MOINS*QUANTITE) <> 0
|
|
|
;
|
|
|
|
|
|
CREATE INDEX w_STOCK_i1 ON w_STOCK USING btree (CODE_ARTICLE);
|
|
|
|
|
|
DROP TABLE IF EXISTS w_STOCK_CURRENT;
|
|
|
CREATE TEMP TABLE w_STOCK_CURRENT AS
|
|
|
SELECT
|
|
|
MAX(mois_sequence) AS CURRENT_mois_sequence,
|
|
|
MAX(date_debut) AS CURRENT_date_debut,
|
|
|
MAX(date_fin) AS CURRENT_date_fin
|
|
|
FROM w_STOCK;
|
|
|
|
|
|
|
|
|
|
|
|
DROP TABLE IF EXISTS w_STOCK_FIN;
|
|
|
CREATE TEMP TABLE w_STOCK_FIN AS
|
|
|
SELECT
|
|
|
CODE_STOCK,
|
|
|
CODE_ARTICLE,
|
|
|
CURRENT_mois_sequence AS mois_sequence,
|
|
|
MAX(CURRENT_date_debut) AS date_debut,
|
|
|
MIN(CURRENT_date_fin) AS date_fin,
|
|
|
SUM(QUANTITE) AS stock_quantite_fin
|
|
|
FROM w_STOCK_CURRENT,
|
|
|
prod_sigems.STOCK
|
|
|
JOIN eco.t_lieux ON CODE_STOCK = t_lieux.code_original AND t_lieux.est_ignore IS DISTINCT FROM '1'
|
|
|
GROUP BY 1,2,3
|
|
|
HAVING SUM(QUANTITE) <> 0;
|
|
|
|
|
|
CREATE INDEX w_STOCK_FIN_i1 ON w_STOCK_FIN USING btree (CODE_ARTICLE);
|
|
|
|
|
|
INSERT INTO w_STOCK
|
|
|
(
|
|
|
CODE_STOCK,
|
|
|
CODE_ARTICLE,
|
|
|
mois_sequence,
|
|
|
date_debut,
|
|
|
date_fin,
|
|
|
stock_quantite_debut,
|
|
|
stock_valeur_debut,
|
|
|
entree_quantite,
|
|
|
entree_montant,
|
|
|
entree_quantite_pump,
|
|
|
entree_montant_pump,
|
|
|
sortie_quantite,
|
|
|
sortie_montant,
|
|
|
sortie_quantite_valorise,
|
|
|
sortie_montant_valorise,
|
|
|
sortie_quantite_non_valorise,
|
|
|
sortie_montant_non_valorise,
|
|
|
stock_quantite_fin,
|
|
|
stock_valeur_fin,
|
|
|
pump,
|
|
|
ok_stock_fin
|
|
|
)
|
|
|
SELECT
|
|
|
w_STOCK_FIN.CODE_STOCK,
|
|
|
w_STOCK_FIN.CODE_ARTICLE,
|
|
|
w_STOCK_FIN.mois_sequence,
|
|
|
w_STOCK_FIN.date_debut,
|
|
|
w_STOCK_FIN.date_fin,
|
|
|
w_STOCK_FIN.stock_quantite_fin AS stock_quantite_debut,
|
|
|
0::numeric AS stock_valeur_debut,
|
|
|
0::numeric AS entree_quantite,
|
|
|
0::numeric AS entree_montant,
|
|
|
0::numeric AS entree_quantite_pump,
|
|
|
0::numeric AS entree_montant_pump,
|
|
|
0::numeric AS sortie_quantite,
|
|
|
0::numeric AS sortie_montant,
|
|
|
0::numeric AS sortie_quantite_valorise,
|
|
|
0::numeric AS sortie_montant_valorise,
|
|
|
0::numeric AS sortie_quantite_non_valorise,
|
|
|
0::numeric AS sortie_montant_non_valorise,
|
|
|
w_STOCK_FIN.stock_quantite_fin,
|
|
|
0::numeric AS stock_valeur_fin,
|
|
|
0::numeric AS pump,
|
|
|
'1'::text AS ok_stock_fin
|
|
|
FROM w_STOCK_FIN
|
|
|
LEFT JOIN w_STOCK ON
|
|
|
w_STOCK_FIN.CODE_STOCK = w_STOCK.CODE_STOCK AND
|
|
|
w_STOCK_FIN.CODE_ARTICLE = w_STOCK.CODE_ARTICLE AND
|
|
|
w_STOCK_FIN.mois_sequence = w_STOCK.mois_sequence
|
|
|
WHERE w_STOCK.CODE_ARTICLE IS NULL;
|
|
|
|
|
|
UPDATE w_STOCK SET
|
|
|
stock_quantite_debut = w_STOCK_FIN.stock_quantite_fin - w_STOCK.entree_quantite + w_STOCK.sortie_quantite,
|
|
|
stock_quantite_fin = w_STOCK_FIN.stock_quantite_fin,
|
|
|
ok_stock_fin = '1'
|
|
|
FROM w_STOCK_FIN
|
|
|
WHERE
|
|
|
w_STOCK_FIN.CODE_STOCK = w_STOCK.CODE_STOCK AND
|
|
|
w_STOCK_FIN.CODE_ARTICLE = w_STOCK.CODE_ARTICLE AND
|
|
|
w_STOCK_FIN.mois_sequence = w_STOCK.mois_sequence;
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
DROP TABLE IF EXISTS w_STOCK_ARTICLE;
|
|
|
CREATE TEMP TABLE w_STOCK_ARTICLE AS
|
|
|
SELECT
|
|
|
CODE_STOCK,
|
|
|
CODE_ARTICLE,
|
|
|
MIN(mois_sequence) AS mois_sequence_debut,
|
|
|
MAX(mois_sequence) AS mois_sequence_fin
|
|
|
FROM w_STOCK
|
|
|
GROUP BY 1,2
|
|
|
;
|
|
|
|
|
|
CREATE INDEX w_STOCK_ARTICLE_i1 ON w_STOCK_ARTICLE USING btree (CODE_ARTICLE);
|
|
|
|
|
|
UPDATE w_STOCK SET
|
|
|
stock_quantite_debut = w_STOCK.stock_quantite_fin - w_STOCK.entree_quantite + w_STOCK.sortie_quantite,
|
|
|
ok_stock_fin = '1'
|
|
|
FROM w_STOCK_ARTICLE
|
|
|
WHERE
|
|
|
w_STOCK_ARTICLE.CODE_STOCK = w_STOCK.CODE_STOCK AND
|
|
|
w_STOCK_ARTICLE.CODE_ARTICLE = w_STOCK.CODE_ARTICLE AND
|
|
|
w_STOCK_ARTICLE.mois_sequence_fin = w_STOCK.mois_sequence AND
|
|
|
ok_stock_fin = '0';
|
|
|
|
|
|
DROP TABLE IF EXISTS w_calendrier_mois;
|
|
|
CREATE TEMP TABLE w_calendrier_mois AS
|
|
|
SELECT
|
|
|
date_part('year',date_debut) * 12 + date_part('month',date_debut) AS mois_sequence,
|
|
|
date_debut,
|
|
|
date_fin
|
|
|
FROM w_STOCK_CURRENT,
|
|
|
base.p_calendrier_mois
|
|
|
WHERE date_debut BETWEEN '[ENV_ECO_ANNEEDEBUT]-01-01' AND CURRENT_date_fin;
|
|
|
|
|
|
CREATE INDEX w_calendrier_mois_i1 ON w_calendrier_mois USING btree (mois_sequence);
|
|
|
|
|
|
INSERT INTO w_STOCK
|
|
|
(
|
|
|
CODE_STOCK,
|
|
|
CODE_ARTICLE,
|
|
|
mois_sequence,
|
|
|
date_debut,
|
|
|
date_fin,
|
|
|
stock_quantite_debut,
|
|
|
stock_valeur_debut,
|
|
|
entree_quantite,
|
|
|
entree_montant,
|
|
|
entree_quantite_pump,
|
|
|
entree_montant_pump,
|
|
|
sortie_quantite,
|
|
|
sortie_montant,
|
|
|
sortie_quantite_valorise,
|
|
|
sortie_montant_valorise,
|
|
|
sortie_quantite_non_valorise,
|
|
|
sortie_montant_non_valorise,
|
|
|
stock_quantite_fin,
|
|
|
stock_valeur_fin,
|
|
|
pump,
|
|
|
ok_stock_fin
|
|
|
)
|
|
|
SELECT
|
|
|
w_STOCK_ARTICLE.CODE_STOCK,
|
|
|
w_STOCK_ARTICLE.CODE_ARTICLE,
|
|
|
w_calendrier_mois.mois_sequence,
|
|
|
w_calendrier_mois.date_debut,
|
|
|
w_calendrier_mois.date_fin,
|
|
|
0::numeric AS stock_quantite_debut,
|
|
|
0::numeric AS stock_valeur_debut,
|
|
|
0::numeric AS entree_quantite,
|
|
|
0::numeric AS entree_montant,
|
|
|
0::numeric AS entree_quantite_pump,
|
|
|
0::numeric AS entree_montant_pump,
|
|
|
0::numeric AS sortie_quantite,
|
|
|
0::numeric AS sortie_montant,
|
|
|
0::numeric AS sortie_quantite_valorise,
|
|
|
0::numeric AS sortie_montant_valorise,
|
|
|
0::numeric AS sortie_quantite_non_valorise,
|
|
|
0::numeric AS sortie_montant_non_valorise,
|
|
|
0::numeric AS stock_quantite_fin,
|
|
|
0::numeric AS stock_valeur_fin,
|
|
|
0::numeric AS pump,
|
|
|
'0'::text AS ok_stock_fin
|
|
|
FROM w_STOCK_ARTICLE
|
|
|
JOIN w_calendrier_mois ON w_calendrier_mois.mois_sequence BETWEEN mois_sequence_debut AND mois_sequence_fin
|
|
|
LEFT JOIN w_STOCK ON
|
|
|
w_STOCK_ARTICLE.CODE_STOCK = w_STOCK.CODE_STOCK AND
|
|
|
w_STOCK_ARTICLE.CODE_ARTICLE = w_STOCK.CODE_ARTICLE AND
|
|
|
w_STOCK.mois_sequence = w_calendrier_mois.mois_sequence
|
|
|
WHERE w_STOCK.CODE_ARTICLE IS NULL;
|
|
|
|
|
|
VACUUM ANALYSE w_STOCK;
|
|
|
|
|
|
|
|
|
SELECT base.cti_execute(
|
|
|
'UPDATE w_STOCK SET
|
|
|
stock_quantite_debut =
|
|
|
w_STOCK_AFTER.stock_quantite_debut -
|
|
|
w_STOCK.entree_quantite +
|
|
|
w_STOCK.sortie_quantite,
|
|
|
stock_quantite_fin =
|
|
|
w_STOCK_AFTER.stock_quantite_debut,
|
|
|
ok_stock_fin = ''1''
|
|
|
FROM w_STOCK w_STOCK_AFTER
|
|
|
WHERE w_STOCK_AFTER.CODE_STOCK = w_STOCK.CODE_STOCK AND
|
|
|
w_STOCK_AFTER.CODE_ARTICLE = w_STOCK.CODE_ARTICLE AND
|
|
|
w_STOCK_AFTER.mois_sequence = w_STOCK.mois_sequence+1 AND
|
|
|
w_STOCK.date_debut >= ''[ENV_ECO_ANNEEDEBUT]-01-01'' AND
|
|
|
w_STOCK_AFTER.ok_stock_fin = ''1'' AND
|
|
|
w_STOCK.ok_stock_fin = ''0''',300) ;
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
-- Nouvelle méthode ou on détermine le PUMP selon historique des prix distri
|
|
|
UPDATE w_STOCK SET
|
|
|
pump = prix_distri_ht,
|
|
|
stock_valeur_fin = w_STOCK.stock_quantite_fin * prix_distri_ht
|
|
|
FROM w_prix_distri
|
|
|
WHERE w_prix_distri.CODE_ARTICLE = w_STOCK.CODE_ARTICLE AND
|
|
|
w_STOCK.date_fin BETWEEN w_prix_distri.date_debut AND w_prix_distri.date_fin
|
|
|
;
|
|
|
|
|
|
|
|
|
UPDATE w_STOCK SET
|
|
|
stock_quantite_debut = w_STOCK_BEFORE.stock_quantite_fin,
|
|
|
stock_valeur_debut = w_STOCK_BEFORE.stock_valeur_fin
|
|
|
FROM w_STOCK w_STOCK_BEFORE
|
|
|
WHERE w_STOCK_BEFORE.CODE_STOCK = w_STOCK.CODE_STOCK AND
|
|
|
w_STOCK_BEFORE.CODE_ARTICLE = w_STOCK.CODE_ARTICLE AND
|
|
|
w_STOCK_BEFORE.mois_sequence = w_STOCK.mois_sequence - 1;
|
|
|
|
|
|
-- maj des pump si inventaire sans mouvement dans période
|
|
|
UPDATE w_STOCK
|
|
|
SET pump = E_PX_UNIT_NET::numeric
|
|
|
FROM prod_sigems.MVT_STOCK
|
|
|
WHERE w_STOCK.CODE_ARTICLE = mvt_stock.CODE_ARTICLE
|
|
|
AND date_mvt BETWEEN w_STOCK.date_debut AND w_stock.date_fin
|
|
|
AND module = 'I' AND entree_quantite = 0 and sortie_quantite = 0
|
|
|
;
|
|
|
|
|
|
SELECT base.cti_disable_index('eco', 'i_stock_1');
|
|
|
SELECT base.cti_disable_index('eco', 'i_stock_2');
|
|
|
SELECT base.cti_disable_index('eco', 'i_stock_3');
|
|
|
SELECT base.cti_disable_index('eco', 'i_stock_4');
|
|
|
SELECT base.cti_disable_index('eco', 'i_stock_5');
|
|
|
|
|
|
|
|
|
TRUNCATE eco.p_stock;
|
|
|
|
|
|
INSERT INTO eco.p_stock(
|
|
|
article_id,
|
|
|
date_fin,
|
|
|
date_debut,
|
|
|
ucd_id,
|
|
|
lpp_id,
|
|
|
compte_id,
|
|
|
lieu_id,
|
|
|
provider_id,
|
|
|
fournisseur_id,
|
|
|
stock_quantite_debut,
|
|
|
stock_valeur_debut,
|
|
|
entree_quantite,
|
|
|
entree_montant,
|
|
|
pump,
|
|
|
sortie_quantite,
|
|
|
sortie_montant,
|
|
|
stock_quantite_fin,
|
|
|
stock_valeur_fin)
|
|
|
|
|
|
SELECT
|
|
|
t_articles.oid AS article_id,
|
|
|
date_fin,
|
|
|
date_debut,
|
|
|
t_articles.ucd_id AS ucd_id,
|
|
|
t_articles.lpp_id AS lpp_id,
|
|
|
t_articles.compte_id AS compte_id,
|
|
|
t_lieux.oid AS lieu_id,
|
|
|
0::bigint AS provider_id,
|
|
|
t_articles.fournisseur_principal_id AS fournisseur_id,
|
|
|
stock_quantite_debut,
|
|
|
stock_valeur_debut,
|
|
|
entree_quantite,
|
|
|
entree_montant,
|
|
|
pump,
|
|
|
sortie_quantite,
|
|
|
sortie_montant,
|
|
|
stock_quantite_fin,
|
|
|
stock_valeur_fin
|
|
|
FROM w_STOCK
|
|
|
JOIN eco.t_articles ON CODE_ARTICLE = t_articles.code_original
|
|
|
JOIN eco.t_lieux ON CODE_STOCK = t_lieux.code_original AND t_lieux.est_ignore IS DISTINCT FROM '1'
|
|
|
WHERE date_debut >= '[ENV_ECO_ANNEEDEBUT]-01-01' AND
|
|
|
|
|
|
(
|
|
|
stock_quantite_debut <> 0 OR
|
|
|
entree_quantite <> 0 OR
|
|
|
sortie_quantite <> 0 OR
|
|
|
stock_quantite_fin <> 0
|
|
|
)
|
|
|
;
|
|
|
|
|
|
SELECT base.cti_enable_index('eco', 'i_stock_1');
|
|
|
SELECT base.cti_enable_index('eco', 'i_stock_2');
|
|
|
SELECT base.cti_enable_index('eco', 'i_stock_3');
|
|
|
SELECT base.cti_enable_index('eco', 'i_stock_4');
|
|
|
SELECT base.cti_enable_index('eco', 'i_stock_5');
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
-- ajout des stocks mensuels manquants
|
|
|
SELECT base.cti_execute('
|
|
|
INSERT INTO eco.p_stock
|
|
|
(
|
|
|
fournisseur_id,
|
|
|
article_id,
|
|
|
compte_id,
|
|
|
ucd_id,
|
|
|
lpp_id,
|
|
|
site_id,
|
|
|
lieu_id,
|
|
|
date_debut,
|
|
|
date_fin,
|
|
|
entree_quantite,
|
|
|
entree_montant,
|
|
|
sortie_quantite,
|
|
|
sortie_montant,
|
|
|
pump,
|
|
|
stock_quantite_debut,
|
|
|
stock_quantite_fin,
|
|
|
stock_valeur_debut,
|
|
|
stock_valeur_fin
|
|
|
)
|
|
|
SELECT
|
|
|
p_stock.fournisseur_id,
|
|
|
p_stock.article_id,
|
|
|
p_stock.compte_id,
|
|
|
p_stock.ucd_id,
|
|
|
p_stock.lpp_id,
|
|
|
p_stock.site_id,
|
|
|
p_stock.lieu_id,
|
|
|
date(date_trunc(''month'',p_stock.date_debut) - interval ''1 month'') AS date_debut,
|
|
|
date(date_trunc(''month'',p_stock.date_debut) - interval ''1 day'') AS date_fin,
|
|
|
0 AS entree_quantite,
|
|
|
0 AS entree_montant,
|
|
|
0 AS sortie_quantite,
|
|
|
0 AS sortie_montant,
|
|
|
p_stock.pump,
|
|
|
p_stock.stock_quantite_debut,
|
|
|
p_stock.stock_quantite_debut,
|
|
|
p_stock.stock_valeur_debut,
|
|
|
p_stock.stock_valeur_debut
|
|
|
FROM eco.p_stock
|
|
|
LEFT JOIN eco.p_stock p_stock_prev ON
|
|
|
p_stock.site_id = p_stock_prev.site_id AND
|
|
|
p_stock.lieu_id = p_stock_prev.lieu_id AND
|
|
|
p_stock.article_id = p_stock_prev.article_id AND
|
|
|
date(date_trunc(''month'',p_stock.date_debut) - interval ''1 day'') = p_stock_prev.date_fin
|
|
|
WHERE
|
|
|
p_stock.date_debut <= now() AND
|
|
|
p_stock.date_fin >= ''2015-01-01'' AND
|
|
|
p_stock.stock_quantite_debut != 0 AND
|
|
|
p_stock_prev.article_id IS NULL
|
|
|
',200)
|
|
|
;
|
|
|
|
|
|
SELECT base.cti_execute('
|
|
|
INSERT INTO eco.p_stock
|
|
|
(
|
|
|
fournisseur_id,
|
|
|
article_id,
|
|
|
compte_id,
|
|
|
ucd_id,
|
|
|
lpp_id,
|
|
|
site_id,
|
|
|
lieu_id,
|
|
|
date_debut,
|
|
|
date_fin,
|
|
|
entree_quantite,
|
|
|
entree_montant,
|
|
|
sortie_quantite,
|
|
|
sortie_montant,
|
|
|
pump,
|
|
|
stock_quantite_debut,
|
|
|
stock_quantite_fin,
|
|
|
stock_valeur_debut,
|
|
|
stock_valeur_fin
|
|
|
)
|
|
|
SELECT
|
|
|
p_stock.fournisseur_id,
|
|
|
p_stock.article_id,
|
|
|
p_stock.compte_id,
|
|
|
p_stock.ucd_id,
|
|
|
p_stock.lpp_id,
|
|
|
p_stock.site_id,
|
|
|
p_stock.lieu_id,
|
|
|
date(date_trunc(''month'',p_stock.date_debut) + interval ''1 month'') AS date_debut,
|
|
|
date(date_trunc(''month'',p_stock.date_debut) + interval ''2 month'' - interval ''1 day'') AS date_fin,
|
|
|
0 AS entree_quantite,
|
|
|
0 AS entree_montant,
|
|
|
0 AS sortie_quantite,
|
|
|
0 AS sortie_montant,
|
|
|
p_stock.pump,
|
|
|
p_stock.stock_quantite_fin,
|
|
|
p_stock.stock_quantite_fin,
|
|
|
p_stock.stock_valeur_fin,
|
|
|
p_stock.stock_valeur_fin
|
|
|
FROM eco.p_stock
|
|
|
LEFT JOIN eco.p_stock p_stock_next ON
|
|
|
p_stock.site_id = p_stock_next.site_id AND
|
|
|
p_stock.lieu_id = p_stock_next.lieu_id AND
|
|
|
p_stock.article_id = p_stock_next.article_id AND
|
|
|
p_stock.date_fin + interval ''1 day'' = p_stock_next.date_debut
|
|
|
WHERE
|
|
|
p_stock.date_debut <= now() AND
|
|
|
p_stock.date_fin >= ''2015-01-01'' AND
|
|
|
p_stock.stock_quantite_fin != 0 AND
|
|
|
p_stock_next.article_id IS NULL
|
|
|
',200)
|
|
|
;
|
|
|
|
|
|
SELECT base.cti_enable_index('eco', 'i_stock_1');
|
|
|
SELECT base.cti_enable_index('eco', 'i_stock_2');
|
|
|
SELECT base.cti_enable_index('eco', 'i_stock_3');
|
|
|
SELECT base.cti_enable_index('eco', 'i_stock_4');
|
|
|
SELECT base.cti_enable_index('eco', 'i_stock_5');
|
|
|
|
|
|
|
|
|
|
|
|
]]></sqlcmd>
|
|
|
</NODE>
|
|
|
|
|
|
|
|
|
<NODE label="Mouvements">
|
|
|
<sqlcmd><![CDATA[
|
|
|
|
|
|
|
|
|
UPDATE w_MVT_STOCK
|
|
|
SET commande_id = p_commandes.oid
|
|
|
FROM eco.p_commandes
|
|
|
WHERE p_commandes.code_original = NUMERO_CDE AND
|
|
|
commande_id = 0
|
|
|
;
|
|
|
|
|
|
UPDATE w_MVT_STOCK
|
|
|
SET commande_id = p_commandes.oid
|
|
|
FROM eco.p_commandes
|
|
|
WHERE p_commandes.numero = NUMERO_CDE_DATE AND
|
|
|
NUMERO_CDE_DATE <> '' AND
|
|
|
commande_id = 0
|
|
|
;
|
|
|
|
|
|
-- Réplication numero de séjour sur entrées si commande citée
|
|
|
UPDATE w_MVT_STOCK MVT_STOCK
|
|
|
SET ANN_DOS = ANN_DOS_CDE, COD_DOS = COD_DOS_CDE
|
|
|
FROM
|
|
|
(
|
|
|
SELECT commande_id, NUMERO_LIGNE, MAX(ANN_DOS) AS ANN_DOS_CDE, MAX(COD_DOS) AS COD_DOS_CDE
|
|
|
FROM w_MVT_STOCK MVT_STOCK
|
|
|
WHERE NUMERO_CDE <> 0 AND ANN_DOS <> ''
|
|
|
GROUP BY 1,2
|
|
|
HAVING count(DISTINCT ANN_DOS||to_char(COD_DOS,'FM900000')) = 1
|
|
|
) subview
|
|
|
WHERE MVT_STOCK.commande_id = subview.commande_id AND
|
|
|
MVT_STOCK.NUMERO_LIGNE = subview.NUMERO_LIGNE AND
|
|
|
MVT_STOCK.ANN_DOS = ''
|
|
|
;
|
|
|
|
|
|
|
|
|
TRUNCATE eco.p_mouvements_articles;
|
|
|
|
|
|
SELECT base.cti_disable_index('eco', 'i_mouvements_articles_1');
|
|
|
SELECT base.cti_disable_index('eco', 'i_mouvements_articles_2');
|
|
|
SELECT base.cti_disable_index('eco', 'i_mouvements_articles_3');
|
|
|
SELECT base.cti_disable_index('eco', 'i_mouvements_articles_4');
|
|
|
SELECT base.cti_disable_index('eco', 'i_mouvements_articles_5');
|
|
|
SELECT base.cti_disable_index('eco', 'i_mouvements_articles_6');
|
|
|
SELECT base.cti_disable_index('eco', 'i_mouvements_articles_7');
|
|
|
SELECT base.cti_disable_index('eco', 'i_mouvements_articles_8');
|
|
|
SELECT base.cti_disable_index('eco', 'i_mouvements_articles_9');
|
|
|
SELECT base.cti_disable_index('eco', 'i_mouvements_articles_10');
|
|
|
|
|
|
|
|
|
INSERT INTO eco.p_mouvements_articles(
|
|
|
code_original,
|
|
|
date,
|
|
|
sens_mouvement,
|
|
|
type_mouvement_id,
|
|
|
texte,
|
|
|
gestionnaire_id,
|
|
|
lieu_id,
|
|
|
unite_fonctionnelle_id,
|
|
|
article_id,
|
|
|
compte_id,
|
|
|
fournisseur_id,
|
|
|
commande_id,
|
|
|
ligne_commande,
|
|
|
ucd_id,
|
|
|
lpp_id,
|
|
|
prix_unitaire,
|
|
|
entree_quantite,
|
|
|
sortie_quantite,
|
|
|
entree_montant,
|
|
|
entree_montant_ht,
|
|
|
sortie_montant,
|
|
|
sortie_montant_ht,
|
|
|
sortie_montant_original_ttc,
|
|
|
sortie_montant_original_ht,
|
|
|
no_sejour,
|
|
|
no_patient,
|
|
|
livraison_code_original
|
|
|
)
|
|
|
SELECT
|
|
|
w_MVT_STOCK.code_original AS code_original,
|
|
|
DATE_MVT AS date,
|
|
|
CASE WHEN PLUS_MOINS = 1 THEN 'E' ELSE 'S' END AS sens_mouvement,
|
|
|
COALESCE(t_types_mouvements.oid,0) AS type_mouvement_id,
|
|
|
libelle AS texte,
|
|
|
w_MVT_STOCK.gestionnaire_id,
|
|
|
COALESCE(t_lieux.oid,0) AS lieu_id,
|
|
|
COALESCE(t_unites_fonctionnelles.oid,0) AS unite_fonctionnelle_id,
|
|
|
COALESCE(t_articles.oid,0) AS article_id,
|
|
|
COALESCE(t_compte.oid,t_articles.compte_id,0) AS compte_id,
|
|
|
COALESCE(t_fournisseurs.oid,0) AS fournisseur_id,
|
|
|
w_MVT_STOCK.commande_id,
|
|
|
w_MVT_STOCK.NUMERO_LIGNE AS ligne_commande,
|
|
|
COALESCE(t_ucd.oid, t_articles.ucd_id, 0) AS ucd_id,
|
|
|
COALESCE(t_lpp.oid, t_articles.lpp_id, 0) AS lpp_id,
|
|
|
E_PX_UNIT_NET AS prix_unitaire,
|
|
|
CASE WHEN PLUS_MOINS > 0 THEN QUANTITE ELSE 0 END AS entree_quantite,
|
|
|
CASE WHEN PLUS_MOINS < 0 THEN QUANTITE ELSE 0 END AS sortie_quantite,
|
|
|
round(CASE WHEN PLUS_MOINS > 0 AND GRATUIT = 'N' THEN QUANTITE*E_PX_UNIT_NET ELSE 0 END*w_ARTICLES_TVA.taux_tva,2) AS entree_montant,
|
|
|
round(CASE WHEN PLUS_MOINS > 0 AND GRATUIT = 'N' THEN QUANTITE*E_PX_UNIT_NET ELSE 0 END,2) AS entree_montant_ht,
|
|
|
round(CASE
|
|
|
WHEN PLUS_MOINS < 0 AND E_PX_UNIT_NET <> 0 THEN QUANTITE*E_PX_UNIT_NET
|
|
|
WHEN PLUS_MOINS < 0 AND E_PX_UNIT_NET = 0 AND E_VALEUR != 0 THEN QUANTITE*p_stock.pump
|
|
|
ELSE 0 END * w_ARTICLES_TVA.taux_tva
|
|
|
,2) AS sortie_montant,
|
|
|
round(CASE
|
|
|
WHEN PLUS_MOINS < 0 AND E_PX_UNIT_NET <> 0 THEN QUANTITE*E_PX_UNIT_NET
|
|
|
WHEN PLUS_MOINS < 0 AND E_PX_UNIT_NET = 0 AND E_VALEUR != 0 THEN QUANTITE*p_stock.pump
|
|
|
ELSE 0 END
|
|
|
,2) AS sortie_montant_ht,
|
|
|
round(CASE
|
|
|
WHEN PLUS_MOINS < 0 AND E_PX_UNIT_NET <> 0 THEN QUANTITE*E_PX_UNIT_NET
|
|
|
WHEN PLUS_MOINS < 0 AND E_PX_UNIT_NET = 0 AND E_VALEUR != 0 THEN QUANTITE*p_stock.pump
|
|
|
ELSE 0 END * w_ARTICLES_TVA.taux_tva
|
|
|
,2) AS sortie_montant_original_ttc,
|
|
|
round(CASE
|
|
|
WHEN PLUS_MOINS < 0 AND E_PX_UNIT_NET <> 0 THEN QUANTITE*E_PX_UNIT_NET
|
|
|
WHEN PLUS_MOINS < 0 AND E_PX_UNIT_NET = 0 AND E_VALEUR != 0 THEN QUANTITE*p_stock.pump
|
|
|
ELSE 0 END
|
|
|
,2) AS sortie_montant_original_ht,
|
|
|
CASE WHEN ANN_DOS <> '' THEN ANN_DOS || to_char(COD_DOS,'FM900000') ELSE '' END AS no_sejour,
|
|
|
CASE WHEN IPP::text != '0' THEN IPP::text ELSE '' END AS no_patient,
|
|
|
LIG_ENTREE::text AS livraison_code_original
|
|
|
FROM w_MVT_STOCK
|
|
|
JOIN w_ARTICLES_TVA ON w_MVT_STOCK.CODE_ARTICLE = w_ARTICLES_TVA.CODE_ARTICLE AND date(DATE_MVT) BETWEEN w_ARTICLES_TVA.date_debut_tva AND w_ARTICLES_TVA.date_fin_tva
|
|
|
LEFT JOIN eco.t_types_mouvements ON NATURE_MVT = t_types_mouvements.code_original
|
|
|
LEFT JOIN eco.t_unites_fonctionnelles ON SERVICE_DEST = t_unites_fonctionnelles.code_original
|
|
|
LEFT JOIN eco.t_articles ON w_MVT_STOCK.CODE_ARTICLE = t_articles.code_original AND t_articles.oid <> 0
|
|
|
LEFT JOIN eco.t_lieux ON CODE_STOCK = t_lieux.code_original
|
|
|
LEFT JOIN eco.t_fournisseurs ON FOURNISSEUR = t_fournisseurs.code_original
|
|
|
LEFT JOIN eco.t_compte ON 'x' = t_compte.code_original AND t_compte.oid <> 0
|
|
|
LEFT JOIN base.t_ucd ON 'x' = t_ucd.code AND t_ucd.oid <> 0
|
|
|
LEFT JOIN base.t_lpp ON 'x' = t_lpp.code AND t_lpp.oid <> 0
|
|
|
LEFT JOIN eco.p_stock ON
|
|
|
p_stock.article_id = t_articles.oid AND
|
|
|
p_stock.lieu_id = t_lieux.oid AND
|
|
|
date(DATE_MVT) BETWEEN p_stock.date_debut AND p_stock.date_fin
|
|
|
;
|
|
|
|
|
|
UPDATE eco.p_commandes
|
|
|
SET
|
|
|
date_reception = date
|
|
|
FROM
|
|
|
(SELECT
|
|
|
commande_id,
|
|
|
max(date) AS date
|
|
|
FROM eco.p_mouvements_articles
|
|
|
GROUP BY 1) sub
|
|
|
WHERE sub.commande_id = p_commandes.oid
|
|
|
;
|
|
|
|
|
|
SELECT base.cti_enable_index('eco', 'i_mouvements_articles_1');
|
|
|
SELECT base.cti_enable_index('eco', 'i_mouvements_articles_2');
|
|
|
SELECT base.cti_enable_index('eco', 'i_mouvements_articles_3');
|
|
|
SELECT base.cti_enable_index('eco', 'i_mouvements_articles_4');
|
|
|
SELECT base.cti_enable_index('eco', 'i_mouvements_articles_5');
|
|
|
SELECT base.cti_enable_index('eco', 'i_mouvements_articles_6');
|
|
|
SELECT base.cti_enable_index('eco', 'i_mouvements_articles_7');
|
|
|
SELECT base.cti_enable_index('eco', 'i_mouvements_articles_8');
|
|
|
SELECT base.cti_enable_index('eco', 'i_mouvements_articles_9');
|
|
|
SELECT base.cti_enable_index('eco', 'i_mouvements_articles_10');
|
|
|
|
|
|
]]></sqlcmd>
|
|
|
</NODE>
|
|
|
|
|
|
|
|
|
<NODE label="Factures">
|
|
|
<sqlcmd><![CDATA[
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
]]></sqlcmd>
|
|
|
</NODE>
|
|
|
|
|
|
</NODE>
|
|
|
|
|
|
<NODE name="POST" label="POST-TRAITEMENTS">
|
|
|
<NODE label="Compléments mouvements">
|
|
|
|
|
|
<sqlcmd><![CDATA[
|
|
|
VACUUM ANALYSE eco.p_mouvements_articles;
|
|
|
VACUUM ANALYSE eco.p_stock;
|
|
|
|
|
|
REINDEX TABLE eco.p_mouvements_articles;
|
|
|
REINDEX TABLE eco.p_stock;
|
|
|
|
|
|
SELECT eco.cti_update_mvt_qte_stock();
|
|
|
SELECT eco.cti_update_mvt_mnt_stock();
|
|
|
|
|
|
]]></sqlcmd>
|
|
|
</NODE>
|
|
|
<NODE label="Compléments séjour">
|
|
|
|
|
|
<sqlcmd><![CDATA[
|
|
|
|
|
|
SELECT eco.cti_reorganize_sejour();
|
|
|
|
|
|
VACUUM ANALYSE eco.p_sejours;
|
|
|
REINDEX TABLE eco.p_sejours;
|
|
|
|
|
|
SELECT eco.cti_reorganize_sejour_ucd_lpp();
|
|
|
]]></sqlcmd>
|
|
|
</NODE>
|
|
|
</NODE>
|
|
|
</ROOT>
|