|
|
<?xml version="1.0" encoding="ISO-8859-1"?>
|
|
|
<ROOT>
|
|
|
<NODE name="INIT" label="INITIALISATIONS">
|
|
|
|
|
|
<NODE label="Tables Articles">
|
|
|
|
|
|
<sqlcmd><![CDATA[
|
|
|
|
|
|
-- Constitution table des produits avec ceux qui ont été supprimés
|
|
|
DROP TABLE IF EXISTS w_PRODUIT_TYPE;
|
|
|
CREATE TEMP TABLE W_PRODUIT_TYPE AS
|
|
|
SELECT ID,
|
|
|
NOM,
|
|
|
CAHPP_ARTICLE_ID,
|
|
|
PMT_COMPTE_ID,
|
|
|
CATEGORIE,
|
|
|
PRODUIT_FAMILLE_ID,
|
|
|
PRODUIT_SOUS_FAMILLE_ID,
|
|
|
REFERENCE,
|
|
|
PRODUIT_FOURNISSEUR_ID,
|
|
|
CIP,
|
|
|
CIP13,
|
|
|
UCD,
|
|
|
UCD13,
|
|
|
CLADIMED
|
|
|
FROM prod_expert_sante.PRODUIT_TYPE
|
|
|
;
|
|
|
|
|
|
ANALYSE w_PRODUIT_TYPE
|
|
|
;
|
|
|
|
|
|
INSERT INTO w_PRODUIT_TYPE
|
|
|
SELECT ID,
|
|
|
(MAX(ARRAY[MADATE::text,NOM]))[2],
|
|
|
(MAX(ARRAY[MADATE::text,CAHPP_ARTICLE_ID]))[2],
|
|
|
(MAX(ARRAY[MADATE::text,PMT_COMPTE_ID::text]))[2]::bigint,
|
|
|
(MAX(ARRAY[MADATE::text,CATEGORIE]))[2],
|
|
|
(MAX(ARRAY[MADATE::text,PRODUIT_FAMILLE_ID::text]))[2]::bigint,
|
|
|
(MAX(ARRAY[MADATE::text,PRODUIT_SOUS_FAMILLE_ID::text]))[2]::bigint,
|
|
|
(MAX(ARRAY[MADATE::text,REFERENCE]))[2],
|
|
|
(MAX(ARRAY[MADATE::text,PRODUIT_FOURNISSEUR_ID::text]))[2]::bigint,
|
|
|
(MAX(ARRAY[MADATE::text,CIP]))[2],
|
|
|
(MAX(ARRAY[MADATE::text,CIP13]))[2],
|
|
|
(MAX(ARRAY[MADATE::text,UCD]))[2],
|
|
|
(MAX(ARRAY[MADATE::text,UCD13]))[2],
|
|
|
(MAX(ARRAY[MADATE::text,CLADIMED]))[2]
|
|
|
FROM prod_expert_sante.LOG_PRODUIT_TYPE
|
|
|
WHERE ID NOT IN (SELECT ID FROM w_PRODUIT_TYPE)
|
|
|
GROUP BY 1
|
|
|
;
|
|
|
|
|
|
CREATE INDEX w_PRODUIT_TYPE_i1 ON w_PRODUIT_TYPE USING BTREE (ID);
|
|
|
|
|
|
-- Forcage des famùille en tant que type
|
|
|
INSERT INTO eco.t_divers (code, texte, valeur, description)
|
|
|
SELECT
|
|
|
'EXPERT_FAM_AS_TYP',
|
|
|
'Forcer les familles en tant que type',
|
|
|
'0',
|
|
|
'0=Non 1=Oui'
|
|
|
WHERE 'EXPERT_FAM_AS_TYP' NOT IN (SELECT code FROM eco.t_divers)
|
|
|
;
|
|
|
|
|
|
-- Exclusion des utilisateurs négatifs
|
|
|
INSERT INTO eco.t_divers (code, texte, valeur, description)
|
|
|
SELECT
|
|
|
'EXPERT_EXCLUDE_UTIL_AUTO',
|
|
|
'Ignorer les mouvements où l''utilisateur est automatique (id < 0)',
|
|
|
'0',
|
|
|
'0=Non 1=Oui'
|
|
|
WHERE 'EXPERT_EXCLUDE_UTIL_AUTO' NOT IN (SELECT code FROM eco.t_divers)
|
|
|
;
|
|
|
|
|
|
|
|
|
-- Exclusion des produits à de commande négatif
|
|
|
INSERT INTO eco.t_divers (code, texte, valeur, description)
|
|
|
SELECT
|
|
|
'EXPERT_EXCLUDE_COM_NEG',
|
|
|
'Ignorer les produits où le numero de commande est négatif',
|
|
|
'0',
|
|
|
'0=Non 1=Oui'
|
|
|
WHERE 'EXPERT_EXCLUDE_COM_NEG' NOT IN (SELECT code FROM eco.t_divers)
|
|
|
;
|
|
|
|
|
|
|
|
|
|
|
|
-- Comptes
|
|
|
INSERT INTO eco.t_compte(code, texte, texte_court, code_original)
|
|
|
SELECT NUMERO, NOM, LEFT(NOM,50), ID
|
|
|
FROM prod_expert_sante.PMT_COMPTE
|
|
|
WHERE ID NOT IN (SELECT code_original FROM eco.t_compte WHERE code_original IS NOT NULL)
|
|
|
AND VISIBLE = 1;
|
|
|
|
|
|
|
|
|
-- unités (verrouillé par ELA)
|
|
|
/*
|
|
|
SELECT base.cti_execute('INSERT INTO eco.t_unites (code_original, code, texte, texte_court)
|
|
|
SELECT UNITE_CIO.CODE,UNITE_CIO.CODE,LIBELLE,INRSGUNI
|
|
|
FROM prod_expert_sante.UNITE_CIO
|
|
|
LEFT JOIN eco.t_unites ON UNITE_CIO.CODE = code_original
|
|
|
WHERE code_original IS NULL',1)
|
|
|
WHERE (SELECT count(*) FROM information_schema.tables WHERE table_name = 'unite_cio' AND table_schema = 'expert_sante') > 0
|
|
|
;
|
|
|
*/
|
|
|
|
|
|
-- ATC
|
|
|
SELECT base.cti_execute('INSERT INTO eco.t_classification_atc(code_original, code, texte, texte_court )
|
|
|
SELECT CLADIMED.CODE, CLADIMED.CODE, LIBELLE, LEFT(LIBELLE,50)
|
|
|
FROM prod_expert_sante.CLADIMED
|
|
|
LEFT JOIN eco.t_classification_atc ON t_classification_atc.code = CLADIMED.CODE
|
|
|
WHERE code_original IS NULL
|
|
|
ORDER BY 1',1)
|
|
|
WHERE (SELECT count(*) FROM information_schema.tables WHERE table_name = 'cladimed' AND table_schema = 'prod_expert_sante') > 0
|
|
|
;
|
|
|
|
|
|
|
|
|
-- Familles d'articles
|
|
|
INSERT INTO eco.t_familles_articles(code_original, code, texte, texte_court )
|
|
|
SELECT ID, ID, NOM, NOM
|
|
|
FROM prod_expert_sante.PRODUIT_FAMILLE
|
|
|
LEFT JOIN eco.t_familles_articles ON code_original = ID
|
|
|
WHERE code_original IS NULL
|
|
|
AND ID = ANY (ARRAY(SELECT PRODUIT_FAMILLE_ID FROM w_PRODUIT_TYPE PRODUIT_TYPE))
|
|
|
ORDER BY 1
|
|
|
;
|
|
|
|
|
|
|
|
|
-- Sous Familles d'articles
|
|
|
INSERT INTO eco.t_sous_familles_articles(code_original, code, texte, texte_court )
|
|
|
SELECT ID, ID, NOM, NOM
|
|
|
FROM prod_expert_sante.PRODUIT_SOUS_FAMILLE
|
|
|
LEFT JOIN eco.t_sous_familles_articles ON code_original = ID
|
|
|
WHERE code_original IS NULL
|
|
|
AND ID = ANY (ARRAY(SELECT PRODUIT_SOUS_FAMILLE_ID FROM w_PRODUIT_TYPE PRODUIT_TYPE))
|
|
|
ORDER BY 1
|
|
|
;
|
|
|
|
|
|
-- Types
|
|
|
INSERT INTO eco.t_types_articles(code_original, code, texte, texte_court )
|
|
|
SELECT ID, ID, NOM, NOM
|
|
|
FROM prod_expert_sante.PRODUIT_FAMILLE
|
|
|
LEFT JOIN eco.t_types_articles ON code_original = ID
|
|
|
WHERE code_original IS NULL
|
|
|
AND ID = ANY (ARRAY(SELECT PRODUIT_FAMILLE_ID from w_PRODUIT_TYPE PRODUIT_TYPE))
|
|
|
AND (SELECT valeur = '1' FROM eco.t_divers WHERE code = 'EXPERT_FAM_AS_TYP')
|
|
|
ORDER BY 1
|
|
|
;
|
|
|
|
|
|
|
|
|
|
|
|
-- Categories d'articles
|
|
|
INSERT INTO eco.t_categories_articles(code_original, code, texte, texte_court )
|
|
|
SELECT CATEGORIE, CATEGORIE, CATEGORIE, CATEGORIE
|
|
|
FROM w_PRODUIT_TYPE PRODUIT_TYPE
|
|
|
LEFT JOIN eco.t_categories_articles ON code_original = CATEGORIE
|
|
|
WHERE code_original IS NULL
|
|
|
AND CATEGORIE !=''
|
|
|
GROUP BY 1,2,3,4
|
|
|
ORDER BY 1
|
|
|
;
|
|
|
|
|
|
-- Articles
|
|
|
INSERT INTO eco.t_articles(code_original, code, texte, texte_court)
|
|
|
SELECT
|
|
|
ID,
|
|
|
ID,
|
|
|
NOM,
|
|
|
LEFT(NOM,50)
|
|
|
FROM w_PRODUIT_TYPE PRODUIT_TYPE
|
|
|
LEFT JOIN eco.t_articles ON code_original = ID
|
|
|
WHERE code_original IS NULL
|
|
|
AND (ID = ANY(ARRAY(
|
|
|
SELECT DISTINCT PRODUIT_TYPE_ID
|
|
|
FROM prod_expert_sante.COMMANDE_GLOBALE_PRODUIT_TYPE
|
|
|
))
|
|
|
OR ID = ANY(ARRAY(
|
|
|
SELECT DISTINCT PRODUIT_TYPE_ID
|
|
|
FROM prod_expert_sante.PRODUIT_TYPE_COMMANDE
|
|
|
)))
|
|
|
ORDER BY 1;
|
|
|
;
|
|
|
|
|
|
UPDATE eco.t_articles
|
|
|
SET
|
|
|
texte = NOM,
|
|
|
texte_court = LEFT(NOM,50)
|
|
|
FROM w_PRODUIT_TYPE PRODUIT_TYPE
|
|
|
WHERE code_original = ID
|
|
|
AND NOM != texte
|
|
|
;
|
|
|
|
|
|
-- ATC
|
|
|
|
|
|
UPDATE eco.t_articles
|
|
|
SET classification_atc_id = t_classification_atc.oid
|
|
|
FROM w_PRODUIT_TYPE PRODUIT_TYPE
|
|
|
JOIN eco.t_classification_atc ON cladimed = code
|
|
|
WHERE ID = t_articles.code_original
|
|
|
;
|
|
|
|
|
|
-- Standard ATC
|
|
|
SELECT eco.cti_reorganize_classification_atc();
|
|
|
|
|
|
|
|
|
-- comptes et tva
|
|
|
UPDATE eco.t_articles
|
|
|
SET
|
|
|
compte_id = t_compte.oid
|
|
|
FROM w_PRODUIT_TYPE PRODUIT_TYPE
|
|
|
LEFT JOIN eco.t_compte ON PMT_COMPTE_ID = t_compte.code_original
|
|
|
WHERE ID = t_articles.code_original
|
|
|
AND t_compte.oid != compte_id
|
|
|
;
|
|
|
|
|
|
UPDATE eco.t_articles
|
|
|
SET
|
|
|
taux_tva_en_cours = TVA/100
|
|
|
FROM
|
|
|
prod_expert_sante.PRODUIT_TYPE_HISTO
|
|
|
WHERE PRODUIT_TYPE_ID = code_original
|
|
|
AND ENCOURS = 1
|
|
|
;
|
|
|
|
|
|
|
|
|
-- unites
|
|
|
/*UPDATE eco.t_articles
|
|
|
SET
|
|
|
unite_distribution_id = t_unites.oid
|
|
|
FROM w_PRODUIT_TYPE PRODUIT_TYPE
|
|
|
LEFT JOIN eco.t_unites ON UCOSKLMS = t_unites.code_original
|
|
|
WHERE ARTSKLMS = t_articles.code_original
|
|
|
AND (ETOSKLMS = ANY (string_to_array('[ETAB_ID]'::text,',')) OR '[ETAB_ID]' = '' OR '[ETAB_ID]' = '-1')
|
|
|
AND t_unites.oid != unite_distribution_id
|
|
|
;
|
|
|
*/
|
|
|
-- types
|
|
|
UPDATE eco.t_articles
|
|
|
SET type_id = t_types_articles.oid
|
|
|
FROM w_PRODUIT_TYPE PRODUIT_TYPE
|
|
|
LEFT JOIN eco.t_types_articles ON PRODUIT_FAMILLE_ID = t_types_articles.code_original
|
|
|
WHERE ID = t_articles.code_original
|
|
|
AND t_types_articles.oid != type_id
|
|
|
AND (SELECT valeur = '1' FROM eco.t_divers WHERE code = 'EXPERT_FAM_AS_TYP')
|
|
|
;
|
|
|
|
|
|
-- categories
|
|
|
UPDATE eco.t_articles
|
|
|
SET
|
|
|
categorie_id = t_categories_articles.oid
|
|
|
FROM w_PRODUIT_TYPE PRODUIT_TYPE
|
|
|
LEFT JOIN eco.t_categories_articles ON CATEGORIE = t_categories_articles.code_original
|
|
|
WHERE ID = t_articles.code_original
|
|
|
AND t_categories_articles.oid != categorie_id
|
|
|
;
|
|
|
|
|
|
UPDATE eco.t_articles
|
|
|
SET
|
|
|
famille_id = COALESCE(t_familles_articles.oid,0),
|
|
|
gere_en_stock = CASE WHEN USAGE_OPTION IN (1,2) THEN '0' ELSE '1' END
|
|
|
FROM w_PRODUIT_TYPE PRODUIT_TYPE
|
|
|
LEFT JOIN prod_expert_sante.PRODUIT_FAMILLE ON PRODUIT_FAMILLE_ID = PRODUIT_FAMILLE.ID
|
|
|
LEFT JOIN eco.t_familles_articles ON PRODUIT_FAMILLE_ID = t_familles_articles.code_original
|
|
|
WHERE PRODUIT_TYPE.ID = t_articles.code_original
|
|
|
AND
|
|
|
(
|
|
|
famille_id <> COALESCE(t_familles_articles.oid,0) OR
|
|
|
gere_en_stock <> CASE WHEN USAGE_OPTION IN (1,2) THEN '0' ELSE '1' END
|
|
|
)
|
|
|
;
|
|
|
-- autres
|
|
|
|
|
|
-- maj des code, textes, sections
|
|
|
|
|
|
|
|
|
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
|
|
|
);
|
|
|
|
|
|
--lpp et ucd
|
|
|
INSERT INTO base.t_lpp (code, texte, texte_court)
|
|
|
SELECT
|
|
|
CODE_CLE, LIBELLE_REDUIT, LIBELLE_REDUIT
|
|
|
FROM
|
|
|
prod_expert_sante.LPP_PRINCIPAL
|
|
|
WHERE 1=1 AND
|
|
|
CODE_CLE NOT IN (SELECT code FROM base.t_lpp) AND
|
|
|
CODE_CLE = ANY (ARRAY(SELECT LPP_CODE from prod_expert_sante.PRODUIT_TYPE_HISTO))
|
|
|
;
|
|
|
|
|
|
-- recalage historique (date debut et date fin etendues)
|
|
|
DROP TABLE IF EXISTS w_PRODUIT_TYPE_HISTO;
|
|
|
CREATE TEMP TABLE w_produit_type_histo AS
|
|
|
SELECT
|
|
|
PRODUIT_TYPE_ID,
|
|
|
CASE WHEN LAG(DATE_EFFET) OVER (PARTITION BY PRODUIT_TYPE_ID ORDER BY DATE_EFFET) IS NOT NULL THEN DATE_EFFET ELSE '1900-01-01'::date END AS DATE_EFFET,
|
|
|
COALESCE(DATE_TRUNC('day',DATE_FIN) + interval '1 day' - interval '1 second','2099-12-31') AS DATE_FIN,
|
|
|
PRIX_UNITAIRE,
|
|
|
LPP_CODE,
|
|
|
TVA
|
|
|
FROM prod_expert_sante.PRODUIT_TYPE_HISTO
|
|
|
;
|
|
|
|
|
|
ANALYSE w_PRODUIT_TYPE_HISTO
|
|
|
;
|
|
|
|
|
|
CREATE INDEX w_PRODUIT_TYPE_HISTO_i1 ON w_PRODUIT_TYPE_HISTO USING BTREE (PRODUIT_TYPE_ID)
|
|
|
;
|
|
|
|
|
|
UPDATE eco.t_articles
|
|
|
SET
|
|
|
lpp_id = t_lpp.oid
|
|
|
FROM
|
|
|
w_PRODUIT_TYPE_HISTO PRODUIT_TYPE_HISTO
|
|
|
JOIN base.t_lpp ON LPP_CODE = t_lpp.code
|
|
|
WHERE 1=1 AND
|
|
|
PRODUIT_TYPE_ID = t_articles.code_original AND
|
|
|
NOW() BETWEEN DATE_EFFET AND COALESCE(DATE_FIN,'2099-12-31') AND
|
|
|
lpp_id != t_lpp.oid
|
|
|
;
|
|
|
|
|
|
SELECT base.cti_execute('
|
|
|
INSERT INTO base.t_ucd (code, texte, texte_court)
|
|
|
SELECT
|
|
|
UCD, LIBELLE, LIBELLE
|
|
|
FROM
|
|
|
prod_expert_sante.PH8_PRINCIPAL
|
|
|
WHERE 1=1 AND
|
|
|
UCD NOT IN (SELECT code FROM base.t_ucd WHERE code IS NOT NULL)
|
|
|
',1)
|
|
|
WHERE (SELECT count(*) FROM information_schema.tables WHERE table_name = 'ph8_principal' AND table_schema = 'prod_expert_sante') > 0
|
|
|
;
|
|
|
|
|
|
UPDATE eco.t_articles
|
|
|
SET
|
|
|
ucd_id = t_ucd.oid
|
|
|
FROM w_PRODUIT_TYPE PRODUIT_TYPE
|
|
|
JOIN base.t_ucd ON UCD = t_ucd.code
|
|
|
WHERE 1=1 AND
|
|
|
PRODUIT_TYPE.ID = t_articles.code_original AND
|
|
|
ucd_id != t_ucd.oid
|
|
|
;
|
|
|
|
|
|
|
|
|
|
|
|
]]></sqlcmd>
|
|
|
</NODE>
|
|
|
|
|
|
|
|
|
<NODE label="Tables Fournisseurs">
|
|
|
<sqlcmd><![CDATA[
|
|
|
|
|
|
|
|
|
-- Fournisseurs
|
|
|
INSERT INTO eco.t_fournisseurs(code_original, code, texte, texte_court)
|
|
|
SELECT
|
|
|
ID,ID, NOM,LEFT(NOM,50)
|
|
|
FROM prod_expert_sante.PRODUIT_FOURNISSEUR
|
|
|
LEFT JOIN eco.t_fournisseurs ON code_original = ID
|
|
|
WHERE ID = ANY (SELECT DISTINCT PRODUIT_FOURNISSEUR_ID FROM w_PRODUIT_TYPE PRODUIT_TYPE)
|
|
|
AND code_original IS NULL;
|
|
|
|
|
|
DROP TABLE IF EXISTS w_fou_addr;
|
|
|
CREATE TEMP TABLE w_fou_addr AS
|
|
|
SELECT
|
|
|
ID,
|
|
|
string_to_array(replace(replace(replace(replace(ADRESSE,chr(10),''),chr(9),' '),'<br>',chr(13)),'<BR>',chr(13)),chr(13)) AS ADRESSE_array,
|
|
|
0::numeric AS ADRESSE_array_length,
|
|
|
''::text AS adresse,
|
|
|
''::text AS cp,
|
|
|
''::text AS ville
|
|
|
FROM prod_expert_sante.PRODUIT_FOURNISSEUR
|
|
|
;
|
|
|
|
|
|
UPDATE w_fou_addr SET
|
|
|
ADRESSE_array_length = array_length(ADRESSE_array,1),
|
|
|
ADRESSE_array[1] = COALESCE(trim(ADRESSE_array[1]),''),
|
|
|
ADRESSE_array[2] = COALESCE(trim(ADRESSE_array[2]),''),
|
|
|
ADRESSE_array[3] = COALESCE(trim(ADRESSE_array[3]),''),
|
|
|
ADRESSE_array[4] = COALESCE(trim(ADRESSE_array[4]),''),
|
|
|
ADRESSE_array[5] = COALESCE(trim(ADRESSE_array[5]),'')
|
|
|
;
|
|
|
|
|
|
UPDATE w_fou_addr SET
|
|
|
cp = trim(substr(ADRESSE_array[ADRESSE_array_length],1,COALESCE(strpos(ADRESSE_array[ADRESSE_array_length],' '),1))),
|
|
|
ville = trim(substr(ADRESSE_array[ADRESSE_array_length],COALESCE(strpos(ADRESSE_array[ADRESSE_array_length],' '),1))),
|
|
|
adresse =
|
|
|
CASE WHEN ADRESSE_array_length > 1 THEN ADRESSE_array[1] ELSE '' END ||
|
|
|
CASE WHEN ADRESSE_array_length > 2 THEN ' ' || ADRESSE_array[2] ELSE '' END ||
|
|
|
CASE WHEN ADRESSE_array_length > 3 THEN ' ' || ADRESSE_array[3] ELSE '' END ||
|
|
|
CASE WHEN ADRESSE_array_length > 4 THEN ' ' || ADRESSE_array[4] ELSE '' END
|
|
|
;
|
|
|
|
|
|
UPDATE w_fou_addr SET
|
|
|
cp = '',
|
|
|
ville = '',
|
|
|
adresse = adresse || cp || ' ' || ville
|
|
|
WHERE cp <> ''AND
|
|
|
(
|
|
|
length(cp) <> 5 OR
|
|
|
substr(upper(ville),1,1) NOT BETWEEN 'A' AND 'Z'
|
|
|
)
|
|
|
;
|
|
|
|
|
|
|
|
|
INSERT INTO base.t_codes_postaux(code, texte, texte_court, departement_id)
|
|
|
SELECT
|
|
|
cp,
|
|
|
MAX(ville),
|
|
|
MAX(LEFT(ville,50)),
|
|
|
MAX(t_departements.oid)
|
|
|
FROM w_fou_addr sub
|
|
|
LEFT JOIN base.t_codes_postaux ON cp = t_codes_postaux.code
|
|
|
JOIN base.t_departements ON
|
|
|
cp NOT LIKE '97%' AND substr(cp,1,2) = t_departements.code OR
|
|
|
cp LIKE '97%' AND substr(cp,1,3) = t_departements.code
|
|
|
WHERE t_codes_postaux.oid IS NULL AND
|
|
|
length(cp) = 5
|
|
|
GROUP BY 1
|
|
|
;
|
|
|
|
|
|
|
|
|
UPDATE eco.t_fournisseurs SET
|
|
|
code = PRODUIT_FOURNISSEUR.ID,
|
|
|
texte = NOM,
|
|
|
texte_court = LEFT(NOM,50),
|
|
|
adresse = w_fou_addr.adresse,
|
|
|
code_postal_id = COALESCE(t_codes_postaux.oid,0),
|
|
|
ville = w_fou_addr.ville,
|
|
|
cedex = '',
|
|
|
telephone = TEL1,
|
|
|
fax = CDE_FAX,
|
|
|
email = CDE_EMAIL,
|
|
|
siret = '',
|
|
|
iban = '',
|
|
|
bic = '',
|
|
|
code_comptable = ''
|
|
|
FROM prod_expert_sante.PRODUIT_FOURNISSEUR
|
|
|
JOIN w_fou_addr ON w_fou_addr.ID = PRODUIT_FOURNISSEUR.ID
|
|
|
LEFT JOIN base.t_codes_postaux ON cp = t_codes_postaux.code
|
|
|
WHERE code_original = PRODUIT_FOURNISSEUR.ID AND
|
|
|
(
|
|
|
t_fournisseurs.texte IS DISTINCT FROM NOM OR
|
|
|
t_fournisseurs.texte_court IS DISTINCT FROM LEFT(NOM,50) OR
|
|
|
t_fournisseurs.adresse IS DISTINCT FROM w_fou_addr.adresse OR
|
|
|
t_fournisseurs.code_postal_id IS DISTINCT FROM COALESCE(t_codes_postaux.oid,0) OR
|
|
|
t_fournisseurs.ville IS DISTINCT FROM w_fou_addr.ville OR
|
|
|
t_fournisseurs.cedex IS DISTINCT FROM '' OR
|
|
|
t_fournisseurs.telephone IS DISTINCT FROM TEL1 OR
|
|
|
t_fournisseurs.fax IS DISTINCT FROM CDE_FAX OR
|
|
|
t_fournisseurs.email IS DISTINCT FROM CDE_EMAIL OR
|
|
|
t_fournisseurs.siret IS DISTINCT FROM '' OR
|
|
|
t_fournisseurs.iban IS DISTINCT FROM '' OR
|
|
|
t_fournisseurs.bic IS DISTINCT FROM '' OR
|
|
|
t_fournisseurs.code_comptable IS DISTINCT FROM ''
|
|
|
)
|
|
|
;
|
|
|
|
|
|
SELECT base.cti_execute('
|
|
|
|
|
|
INSERT INTO eco.t_fournisseurs(code_original, code, texte, texte_court)
|
|
|
SELECT
|
|
|
''CAHPP'' || DISTRIBUTEUR.ID::text,DISTRIBUTEUR.CODE, DISTRIBUTEUR.NOM,LEFT(DISTRIBUTEUR.NOM,50)
|
|
|
FROM prod_expert_sante.DISTRIBUTEUR
|
|
|
LEFT JOIN eco.t_fournisseurs ON code_original = ''CAHPP'' || DISTRIBUTEUR.ID::text
|
|
|
WHERE ID = ANY (SELECT DISTINCT CAHPP_DISTRIBUTEUR_ID FROM prod_expert_sante.PRODUIT_FOURNISSEUR)
|
|
|
AND code_original IS NULL
|
|
|
.,
|
|
|
|
|
|
UPDATE eco.t_fournisseurs SET
|
|
|
code_cahpp = DISTRIBUTEUR.CODE,
|
|
|
fourniteur_distributeur_id = dis.oid
|
|
|
FROM prod_expert_sante.PRODUIT_FOURNISSEUR
|
|
|
LEFT JOIN prod_expert_sante.DISTRIBUTEUR ON CAHPP_DISTRIBUTEUR_ID = DISTRIBUTEUR.ID
|
|
|
LEFT JOIN eco.t_fournisseurs dis ON ''CAHPP'' || ID::text = dis.code_original
|
|
|
WHERE code_original = ID AND
|
|
|
t_fournisseurs.code_cahpp IS DISTINCT FROM CAHPP_REFERENCE OR
|
|
|
',1)
|
|
|
WHERE (SELECT count(*) FROM information_schema.tables WHERE table_name = 'distributeur' AND table_schema = 'expert_sante') > 0
|
|
|
;
|
|
|
]]></sqlcmd>
|
|
|
</NODE>
|
|
|
|
|
|
|
|
|
<NODE label="Compléments articles">
|
|
|
<sqlcmd><![CDATA[
|
|
|
SELECT base.cti_execute('CREATE TABLE prod_expert_sante.article(id integer,
|
|
|
nom text,
|
|
|
designation_complementaire text,
|
|
|
type_catalogue text,
|
|
|
cahpp_reference text,
|
|
|
fabricant_id integer,
|
|
|
distributeur_id integer,
|
|
|
reference text,
|
|
|
conditionnement integer,
|
|
|
cip text,
|
|
|
atc text,
|
|
|
ucd text,
|
|
|
prix_public real,
|
|
|
prix_cahpp real,
|
|
|
tva real,
|
|
|
forme text,
|
|
|
info_article text,
|
|
|
famille text,
|
|
|
sous_famille text,
|
|
|
madate timestamp without time zone,
|
|
|
fiche_technique text,
|
|
|
date_fin timestamp without time zone,
|
|
|
cip13 text,
|
|
|
ucd13 text,
|
|
|
qml integer,
|
|
|
unite_commande text,
|
|
|
etat smallint
|
|
|
)',1)
|
|
|
WHERE (SELECT count(*) FROM information_schema.tables WHERE table_name = 'article' AND table_schema = 'prod_expert_sante') = 0
|
|
|
;
|
|
|
|
|
|
|
|
|
DROP TABLE IF EXISTS w_PRODUIT_TYPE_FOURNISSEUR;
|
|
|
CREATE TEMP TABLE w_PRODUIT_TYPE_FOURNISSEUR AS
|
|
|
SELECT PRODUIT_TYPE_ID, PRODUIT_FOURNISSEUR_ID
|
|
|
FROM prod_expert_sante.PRODUIT
|
|
|
WHERE PRODUIT_FOURNISSEUR_ID <> 0
|
|
|
GROUP BY 1,2
|
|
|
UNION
|
|
|
SELECT PRODUIT_TYPE_ID, PRODUIT_FOURNISSEUR_ID
|
|
|
FROM prod_expert_sante.LOG_PRODUIT_1
|
|
|
WHERE PRODUIT_FOURNISSEUR_ID <> 0
|
|
|
GROUP BY 1,2
|
|
|
UNION
|
|
|
SELECT PRODUIT_TYPE_ID, PRODUIT_FOURNISSEUR_ID
|
|
|
FROM prod_expert_sante.LOG_PRODUIT_2
|
|
|
WHERE PRODUIT_FOURNISSEUR_ID <> 0
|
|
|
GROUP BY 1,2
|
|
|
UNION
|
|
|
SELECT PRODUIT_TYPE_ID, PRODUIT_FOURNISSEUR_ID
|
|
|
FROM prod_expert_sante.LOG_PRODUIT_3
|
|
|
WHERE PRODUIT_FOURNISSEUR_ID <> 0
|
|
|
GROUP BY 1,2
|
|
|
UNION
|
|
|
SELECT PRODUIT_TYPE_ID, PRODUIT_FOURNISSEUR_ID
|
|
|
FROM prod_expert_sante.LOG_PRODUIT_4
|
|
|
WHERE PRODUIT_FOURNISSEUR_ID <> 0
|
|
|
GROUP BY 1,2
|
|
|
;
|
|
|
|
|
|
ANALYSE w_PRODUIT_TYPE_FOURNISSEUR
|
|
|
;
|
|
|
|
|
|
|
|
|
DROP TABLE IF EXISTS w_PRODUIT_TYPE_HISTO_PU;
|
|
|
CREATE TEMP TABLE w_PRODUIT_TYPE_HISTO_PU AS
|
|
|
SELECT PRODUIT_TYPE_ID,
|
|
|
(MAX(ARRAY[ENCOURS::text, DATE_EFFET::text, PRIX_UNITAIRE::text]))[3]::numeric AS PRIX_UNITAIRE
|
|
|
FROM prod_expert_sante.PRODUIT_TYPE_HISTO
|
|
|
GROUP BY 1
|
|
|
;
|
|
|
|
|
|
ANALYSE w_PRODUIT_TYPE_HISTO_PU
|
|
|
;
|
|
|
|
|
|
|
|
|
DROP TABLE IF EXISTS w_articles_fournisseur_eco;
|
|
|
CREATE TEMP TABLE w_articles_fournisseur_eco AS
|
|
|
SELECT
|
|
|
PRODUIT_TYPE.ID::text || '-' || PRODUIT_TYPE.PRODUIT_FOURNISSEUR_ID::text AS code_original,
|
|
|
t_articles.oid as article_id,
|
|
|
t_fournisseurs.oid as fournisseur_id,
|
|
|
'1'::text AS est_fournisseur_principal,
|
|
|
COALESCE(ARTICLE.NOM,PRODUIT_TYPE.NOM) AS ref_fournisseur_texte,
|
|
|
COALESCE(ARTICLE.REFERENCE,PRODUIT_TYPE.REFERENCE) AS ref_fournisseur_code,
|
|
|
COALESCE(NULLIF(ARTICLE.CIP13,''),NULLIF(PRODUIT_TYPE.CIP13,''),NULLIF(ARTICLE.CIP,''),PRODUIT_TYPE.CIP) as code_cip,
|
|
|
COALESCE(NULLIF(ARTICLE.UCD,''),PRODUIT_TYPE.UCD) as ucd_code,
|
|
|
ucd_id,
|
|
|
lpp_id,
|
|
|
COALESCE(NULLIF(ARTICLE.UCD13,''), PRODUIT_TYPE.UCD13) AS code_ucd13,
|
|
|
COALESCE(CAHPP_ARTICLE_ID,'') AS code_cahpp,
|
|
|
COALESCE(t_unites.oid,0) AS unite_approvisionnement_id,
|
|
|
COALESCE(w_PRODUIT_TYPE_HISTO_PU.PRIX_UNITAIRE,PRIX_CAHPP::numeric,0) AS prix_unitaire_en_cours,
|
|
|
COALESCE(t_compte.oid,0) as compte_id,
|
|
|
COALESCE(CONDITIONNEMENT,1) AS nombre_conditionnement_approvisionnement
|
|
|
FROM w_PRODUIT_TYPE PRODUIT_TYPE
|
|
|
LEFT JOIN w_PRODUIT_TYPE_HISTO_PU ON PRODUIT_TYPE.ID = w_PRODUIT_TYPE_HISTO_PU.PRODUIT_TYPE_ID
|
|
|
JOIN eco.t_articles ON PRODUIT_TYPE.ID = t_articles.code_original
|
|
|
LEFT JOIN prod_expert_sante.ARTICLE ON CAHPP_ARTICLE_ID = CAHPP_REFERENCE AND now() BETWEEN MADATE AND COALESCE(DATE_FIN,'2099-12-31')
|
|
|
JOIN eco.t_fournisseurs ON PRODUIT_TYPE.PRODUIT_FOURNISSEUR_ID = t_fournisseurs.code_original
|
|
|
LEFT JOIN eco.t_unites ON UNITE_COMMANDE = t_unites.code_original
|
|
|
LEFT JOIN eco.t_compte ON PMT_COMPTE_ID = t_compte.code_original
|
|
|
;
|
|
|
|
|
|
|
|
|
/* UPDATE w_articles_fournisseur_eco
|
|
|
SET
|
|
|
ref_fournisseur_code = CASE WHEN w_articles_fournisseur_eco.ref_fournisseur_code = '' THEN sub.ref_fournisseur_code ELSE w_articles_fournisseur_eco.ref_fournisseur_code END,
|
|
|
prix_unitaire_en_cours = CASE WHEN w_articles_fournisseur_eco.prix_unitaire_en_cours = 0 THEN sub.prix_unitaire_en_cours::numeric ELSE w_articles_fournisseur_eco.prix_unitaire_en_cours END
|
|
|
FROM
|
|
|
(SELECT
|
|
|
ETSSALCA || '-' || ARTSALCA || '-' || FOUSACDA AS code_original,
|
|
|
(MAX(Array[
|
|
|
CASE WHEN RFOSALCA != '' OR split_part(split_part(INTSALCA,' REF ',2),' ',1) != '' THEN DCDSACDA::text ELSE '1900-01-01' END,
|
|
|
CASE
|
|
|
WHEN RFOSALCA != '' THEN RFOSALCA
|
|
|
WHEN INTSALCA LIKE '% REF%' THEN split_part(split_part(INTSALCA,' REF ',2),' ',1)
|
|
|
ELSE INTSALCA
|
|
|
END]))[2] AS ref_fournisseur_code,
|
|
|
(MAX(ARRAY[DCDSACDA::text,PVCSALCA::text]))[2]::numeric AS prix_unitaire_en_cours
|
|
|
FROM prod_expert_sante.SACDA
|
|
|
JOIN prod_expert_sante.SALCA ON ETSSALCA || '-' || NUISALCA = ETSSACDA || '-' || NUISACDA
|
|
|
WHERE ( ETSSACDA = ANY(string_to_array('[ETAB_ID]'::text,',')) OR '[ETAB_ID]' = '' OR '[ETAB_ID]' = '-1')
|
|
|
AND FOUSACDA != ''
|
|
|
GROUP BY 1
|
|
|
ORDER BY 1
|
|
|
) sub
|
|
|
WHERE sub.code_original = w_articles_fournisseur_eco.code_original
|
|
|
AND (w_articles_fournisseur_eco.ref_fournisseur_code != sub.ref_fournisseur_code OR w_articles_fournisseur_eco.prix_unitaire_en_cours = 0)
|
|
|
;
|
|
|
|
|
|
*/
|
|
|
|
|
|
INSERT INTO base.t_ucd (code, texte, texte_court)
|
|
|
SELECT ucd_code, ucd_code, ucd_code
|
|
|
FROM w_articles_fournisseur_eco
|
|
|
WHERE ucd_code != ''
|
|
|
AND ucd_code != ALL (ARRAY(SELECT code FROM base.t_ucd))
|
|
|
AND ucd_code LIKE '9%'
|
|
|
GROUP BY 1,2,3
|
|
|
;
|
|
|
|
|
|
UPDATE w_articles_fournisseur_eco
|
|
|
SET ucd_id = t_ucd.oid
|
|
|
FROM base.t_ucd
|
|
|
WHERE 1=1 AND
|
|
|
t_ucd.code = ucd_code AND
|
|
|
w_articles_fournisseur_eco.ucd_id != t_ucd.oid
|
|
|
;
|
|
|
|
|
|
UPDATE eco.t_articles
|
|
|
SET
|
|
|
ucd_id = t_article_fournisseur.ucd_id
|
|
|
FROM
|
|
|
eco.t_article_fournisseur
|
|
|
WHERE 1=1 AND
|
|
|
t_articles.ucd_id != t_article_fournisseur.ucd_id AND
|
|
|
article_id = t_articles.oid
|
|
|
;
|
|
|
|
|
|
-- Référence article fournisseur
|
|
|
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(w_articles_fournisseur_eco.ref_fournisseur_code) AS ref_fournisseur_code,
|
|
|
base.cti_group_array3(CASE WHEN w_articles_fournisseur_eco.ref_fournisseur_texte != '' THEN w_articles_fournisseur_eco.ref_fournisseur_texte ELSE texte END || CASE WHEN w_articles_fournisseur_eco.ref_fournisseur_code != '' AND w_articles_fournisseur_eco.ref_fournisseur_code != w_articles_fournisseur_eco.ref_fournisseur_texte THEN '(' || w_articles_fournisseur_eco.ref_fournisseur_code || ')' ELSE '' END) AS ref_fournisseur_texte
|
|
|
FROM
|
|
|
w_articles_fournisseur_eco
|
|
|
JOIN eco.t_articles ON article_id = t_articles.oid
|
|
|
GROUP BY 1
|
|
|
ORDER BY 2,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
|
|
|
)
|
|
|
;
|
|
|
|
|
|
INSERT INTO eco.t_article_fournisseur (
|
|
|
code_original,
|
|
|
article_id,
|
|
|
fournisseur_id,
|
|
|
code_reference_fournisseur,
|
|
|
texte_reference_fournisseur,
|
|
|
code_cip,
|
|
|
ucd_id,
|
|
|
code_ucd13,
|
|
|
lpp_id,
|
|
|
code_cahpp,
|
|
|
unite_approvisionnement_id,
|
|
|
nombre_conditionnement_approvisionnement,
|
|
|
prix_unitaire_en_cours,
|
|
|
est_fournisseur_principal
|
|
|
)
|
|
|
SELECT
|
|
|
code_original,
|
|
|
article_id,
|
|
|
fournisseur_id,
|
|
|
ref_fournisseur_code,
|
|
|
ref_fournisseur_texte,
|
|
|
code_cip,
|
|
|
ucd_id,
|
|
|
code_ucd13,
|
|
|
lpp_id,
|
|
|
code_cahpp,
|
|
|
unite_approvisionnement_id,
|
|
|
nombre_conditionnement_approvisionnement,
|
|
|
prix_unitaire_en_cours,
|
|
|
est_fournisseur_principal
|
|
|
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,
|
|
|
code_reference_fournisseur = w_articles_fournisseur_eco.ref_fournisseur_code,
|
|
|
texte_reference_fournisseur = w_articles_fournisseur_eco.ref_fournisseur_texte,
|
|
|
code_cip = w_articles_fournisseur_eco.code_cip,
|
|
|
code_ucd13 = w_articles_fournisseur_eco.code_ucd13,
|
|
|
ucd_id = w_articles_fournisseur_eco.ucd_id,
|
|
|
lpp_id = w_articles_fournisseur_eco.lpp_id,
|
|
|
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,
|
|
|
est_fournisseur_principal = w_articles_fournisseur_eco.est_fournisseur_principal
|
|
|
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.code_reference_fournisseur IS DISTINCT FROM w_articles_fournisseur_eco.ref_fournisseur_code OR
|
|
|
t_article_fournisseur.texte_reference_fournisseur IS DISTINCT FROM w_articles_fournisseur_eco.ref_fournisseur_texte OR
|
|
|
t_article_fournisseur.code_cip IS DISTINCT FROM w_articles_fournisseur_eco.code_cip OR
|
|
|
t_article_fournisseur.code_ucd13 IS DISTINCT FROM w_articles_fournisseur_eco.code_ucd13 OR
|
|
|
t_article_fournisseur.ucd_id IS DISTINCT FROM w_articles_fournisseur_eco.ucd_id OR
|
|
|
t_article_fournisseur.lpp_id IS DISTINCT FROM w_articles_fournisseur_eco.lpp_id 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.est_fournisseur_principal IS DISTINCT FROM w_articles_fournisseur_eco.est_fournisseur_principal
|
|
|
)
|
|
|
;
|
|
|
|
|
|
|
|
|
]]></sqlcmd>
|
|
|
</NODE>
|
|
|
|
|
|
|
|
|
|
|
|
<NODE label="Autres tables">
|
|
|
<sqlcmd><![CDATA[
|
|
|
|
|
|
-- Gestionnaires
|
|
|
|
|
|
INSERT INTO eco.t_gestionnaires(code_original, code, texte, texte_court)
|
|
|
SELECT ID::text, ID::text, NOM || ' ' || PRENOM, LEFT(NOM || ' ' || LEFT(PRENOM,1),50)
|
|
|
FROM prod_expert_sante.UTILISATEUR
|
|
|
WHERE ID <> 0 AND
|
|
|
ID::text NOT IN (SELECT CODE_ORIGINAL FROM eco.t_gestionnaires)
|
|
|
;
|
|
|
;
|
|
|
|
|
|
-- Site
|
|
|
INSERT INTO eco.t_sites(code_original, code, texte, texte_court)
|
|
|
SELECT ID, ID, NOM, LEFT(NOM,50)
|
|
|
FROM prod_expert_sante.ETAGE
|
|
|
LEFT JOIN eco.t_sites ON (code_original = ID)
|
|
|
WHERE code_original IS NULL
|
|
|
;
|
|
|
|
|
|
|
|
|
-- Lieux
|
|
|
INSERT INTO eco.t_lieux(code_original, code, texte, texte_court)
|
|
|
SELECT ID, ID, NOM, LEFT(NOM,50)
|
|
|
FROM prod_expert_sante.STOCK
|
|
|
LEFT JOIN eco.t_lieux ON (code_original = ID)
|
|
|
WHERE code_original IS NULL
|
|
|
;
|
|
|
|
|
|
|
|
|
-- UF
|
|
|
INSERT INTO eco.t_unites_fonctionnelles(code_original, code, texte, texte_court)
|
|
|
SELECT ID, ID, NOM, LEFT(NOM,50)
|
|
|
FROM prod_expert_sante.SERVICE
|
|
|
LEFT JOIN eco.t_unites_fonctionnelles ON (code_original = ID)
|
|
|
WHERE code_original IS NULL
|
|
|
;
|
|
|
|
|
|
-- Types mouvements
|
|
|
DROP TABLE IF EXISTS w_type_mouvement;
|
|
|
CREATE TEMP TABLE w_type_mouvement (c_o text,c text,t text,t_c text);
|
|
|
INSERT INTO w_type_mouvement
|
|
|
VALUES
|
|
|
('LID','LIV','Livraison fournisseur','Livraison fournisseur'),
|
|
|
('REF','RET_F','Retour fournisseur','Retour fournisseur'),
|
|
|
('TRS','TRS','Transfert','Transfert'),
|
|
|
('DIS','DIS','Distribution','Distribution'),
|
|
|
('RES','RET_S','Retour service','Retour service'),
|
|
|
('SOD','SOR_D','Consommation','Consommation'),
|
|
|
('SOC','SOR_C','Consommation nominative','Consommation nominative'),
|
|
|
('INV','INV','Correction suite inventaire','Correction suite inventaire'),
|
|
|
('PER','PER','Casse et périmés','Casse et périmés')
|
|
|
|
|
|
;
|
|
|
|
|
|
INSERT INTO eco.t_types_mouvements(code_original, code, texte, texte_court)
|
|
|
SELECT c_o,c,t,t_c FROM w_type_mouvement
|
|
|
LEFT JOIN eco.t_types_mouvements ON c_o = code_original
|
|
|
WHERE code_original IS NULL
|
|
|
;
|
|
|
]]></sqlcmd>
|
|
|
</NODE>
|
|
|
|
|
|
|
|
|
</NODE>
|
|
|
<NODE name="PROD" label="RECUPERATION DES DONNEES DE PRODUCTION">
|
|
|
|
|
|
|
|
|
<NODE label="Commandes">
|
|
|
<sqlcmd><![CDATA[
|
|
|
|
|
|
DROP TABLE IF EXISTS w_PRODUIT_SUPPRIME;
|
|
|
CREATE TEMP TABLE w_PRODUIT_SUPPRIME AS
|
|
|
SELECT COMMANDE_NUMERO, PRODUIT_TYPE_ID, SUM(NOMBRE) AS QUANTITE_SUPPRIME
|
|
|
FROM prod_expert_sante.PRODUIT_SUPPRIME
|
|
|
GROUP BY 1,2
|
|
|
;
|
|
|
|
|
|
ANALYSE w_PRODUIT_SUPPRIME
|
|
|
;
|
|
|
|
|
|
DROP TABLE IF EXISTS w_com;
|
|
|
CREATE TEMP TABLE w_com AS
|
|
|
SELECT
|
|
|
COMMANDE.NUMERO::text || '-' || PRODUIT_TYPE.PRODUIT_FOURNISSEUR_ID || '-' || PRODUIT_TYPE_COMMANDE.PRODUIT_TYPE_ID AS code_original_ligne,
|
|
|
COMMANDE.NUMERO::text AS COMMANDE_NUMERO,
|
|
|
COMMANDE.QUI,
|
|
|
COMMANDE.DATE_CREATION,
|
|
|
PRODUIT_TYPE_COMMANDE.PRODUIT_TYPE_ID,
|
|
|
0::bigint AS PRODUIT_ID,
|
|
|
MAX(PRODUIT_TYPE.PRODUIT_FOURNISSEUR_ID) AS PRODUIT_FOURNISSEUR_ID,
|
|
|
SUM(QUANTITE) - COALESCE(MAX(QUANTITE_SUPPRIME),0) AS QUANTITE,
|
|
|
MAX(PRIX_UNITAIRE) AS PRIX_UNITAIRE,
|
|
|
MAX(STOCK_DESTINATAIRE_ID) AS STOCK_DESTINATAIRE_ID,
|
|
|
MAX(TVA) AS TVA
|
|
|
FROM prod_expert_sante.COMMANDE
|
|
|
JOIN prod_expert_sante.PRODUIT_TYPE_COMMANDE ON COMMANDE.NUMERO = COMMANDE_NUMERO
|
|
|
LEFT JOIN w_PRODUIT_TYPE PRODUIT_TYPE ON PRODUIT_TYPE_ID = PRODUIT_TYPE.ID
|
|
|
LEFT JOIN w_PRODUIT_TYPE_HISTO PRODUIT_TYPE_HISTO ON PRODUIT_TYPE_HISTO.PRODUIT_TYPE_ID = PRODUIT_TYPE.ID AND DATE_CREATION BETWEEN DATE_EFFET AND COALESCE(DATE_FIN,'2099-12-31')
|
|
|
LEFT JOIN w_PRODUIT_SUPPRIME ON
|
|
|
PRODUIT_TYPE_COMMANDE.COMMANDE_NUMERO = w_PRODUIT_SUPPRIME.COMMANDE_NUMERO AND
|
|
|
PRODUIT_TYPE_COMMANDE.PRODUIT_TYPE_ID = w_PRODUIT_SUPPRIME.PRODUIT_TYPE_ID
|
|
|
WHERE DATE_CREATION >= '[ENV_ECO_ANNEEDEBUT]-01-01'
|
|
|
GROUP BY 1,2,3,4,5
|
|
|
HAVING (SUM(QUANTITE) - COALESCE(MAX(QUANTITE_SUPPRIME),0)) <> 0
|
|
|
;
|
|
|
|
|
|
ANALYSE w_com
|
|
|
;
|
|
|
|
|
|
|
|
|
DROP TABLE IF EXISTS w_log_produit;
|
|
|
CREATE TEMP TABLE w_log_produit AS
|
|
|
SELECT subview.*, ID::text||'-'||row_number() OVER (PARTITION BY ID ORDER BY QUAND, STOCK_ID) AS code_original_cti, 0::bigint AS SEJOUR_ID, ''::text AS EXTERNAL_SEJOUR_ID
|
|
|
FROM
|
|
|
(
|
|
|
SELECT ID, PRODUIT_TYPE_ID, EXEMPLAIRE, PRODUIT_TYPE_ETAT_ID, QUAND, STOCK_ID, NUMERO, DATE_RECEPTION, UTILISATEUR_ID, PRODUIT_FOURNISSEUR_ID FROM prod_expert_sante.PRODUIT GROUP BY 1,2,3,4,5,6,7,8,9,10
|
|
|
UNION ALL
|
|
|
SELECT ID, PRODUIT_TYPE_ID, EXEMPLAIRE, PRODUIT_TYPE_ETAT_ID, QUAND, STOCK_ID, NUMERO, DATE_RECEPTION, UTILISATEUR_ID, PRODUIT_FOURNISSEUR_ID FROM prod_expert_sante.LOG_PRODUIT_4 GROUP BY 1,2,3,4,5,6,7,8,9,10
|
|
|
UNION ALL
|
|
|
SELECT ID, PRODUIT_TYPE_ID, EXEMPLAIRE, PRODUIT_TYPE_ETAT_ID, QUAND, STOCK_ID, NUMERO, DATE_RECEPTION, UTILISATEUR_ID, PRODUIT_FOURNISSEUR_ID FROM prod_expert_sante.LOG_PRODUIT_3 GROUP BY 1,2,3,4,5,6,7,8,9,10
|
|
|
UNION ALL
|
|
|
SELECT ID, PRODUIT_TYPE_ID, EXEMPLAIRE, PRODUIT_TYPE_ETAT_ID, QUAND, STOCK_ID, NUMERO, DATE_RECEPTION, UTILISATEUR_ID, PRODUIT_FOURNISSEUR_ID FROM prod_expert_sante.LOG_PRODUIT_2 GROUP BY 1,2,3,4,5,6,7,8,9,10
|
|
|
UNION ALL
|
|
|
SELECT ID, PRODUIT_TYPE_ID, EXEMPLAIRE, PRODUIT_TYPE_ETAT_ID, QUAND, STOCK_ID, NUMERO, DATE_RECEPTION, UTILISATEUR_ID, PRODUIT_FOURNISSEUR_ID FROM prod_expert_sante.LOG_PRODUIT_1 GROUP BY 1,2,3,4,5,6,7,8,9,10
|
|
|
UNION ALL
|
|
|
SELECT ID, PRODUIT_TYPE_ID, EXEMPLAIRE, PRODUIT_TYPE_ETAT_ID, QUAND, STOCK_ID, NUMERO, DATE_RECEPTION, UTILISATEUR_ID, PRODUIT_FOURNISSEUR_ID FROM prod_expert_sante.LOG_PRODUIT GROUP BY 1,2,3,4,5,6,7,8,9,10
|
|
|
) subview
|
|
|
LEFT JOIN eco.t_divers util ON util.code = 'EXPERT_EXCLUDE_UTIL_AUTO'
|
|
|
WHERE util.valeur IS DISTINCT FROM '1' OR (UTILISATEUR_ID >= 0 AND NUMERO >= 0)
|
|
|
;
|
|
|
|
|
|
ANALYSE w_log_produit
|
|
|
;
|
|
|
|
|
|
CREATE INDEX w_log_produit_i1 ON w_log_produit USING BTREE (NUMERO);
|
|
|
CREATE INDEX w_log_produit_i2 ON w_log_produit USING BTREE (PRODUIT_TYPE_ID);
|
|
|
CREATE INDEX w_log_produit_i3 ON w_log_produit USING BTREE (EXEMPLAIRE);
|
|
|
CREATE INDEX w_log_produit_i4 ON w_log_produit USING BTREE (ID);
|
|
|
|
|
|
SELECT base.cti_execute('UPDATE w_log_produit
|
|
|
SET SEJOUR_ID = CASE WHEN ACTE_PRODUIT.SEJOUR_ID > 0 THEN ACTE_PRODUIT.SEJOUR_ID ELSE INTERVENTION.SEJOUR_ID END
|
|
|
FROM prod_expert_sante.ACTE_PRODUIT
|
|
|
LEFT JOIN prod_expert_sante.INTERVENTION ON INTERVENTION_ID = INTERVENTION.ID
|
|
|
WHERE PRODUIT_ID = w_log_produit.ID AND
|
|
|
(ACTE_PRODUIT.SEJOUR_ID > 0 OR INTERVENTION.SEJOUR_ID > 0)',1)
|
|
|
WHERE (SELECT count(*) FROM information_schema.tables WHERE table_name = 'ACTE_PRODUIT' AND table_schema = 'prod_expert_sante') > 0;
|
|
|
|
|
|
UPDATE w_log_produit
|
|
|
SET SEJOUR_ID = CASE WHEN ACTE_PRODUIT.SEJOUR_ID > 0 THEN ACTE_PRODUIT.SEJOUR_ID ELSE INTERVENTION.SEJOUR_ID END
|
|
|
FROM prod_expert_sante.ACTE_PRODUIT
|
|
|
LEFT JOIN prod_expert_sante.INTERVENTION ON INTERVENTION_ID = INTERVENTION.ID
|
|
|
WHERE PRODUIT_ID = w_log_produit.ID AND
|
|
|
(ACTE_PRODUIT.SEJOUR_ID > 0 OR INTERVENTION.SEJOUR_ID > 0)
|
|
|
;
|
|
|
|
|
|
ANALYSE w_log_produit
|
|
|
;
|
|
|
|
|
|
UPDATE w_log_produit
|
|
|
SET EXTERNAL_SEJOUR_ID = SEJOUR.EXTERNAL_SEJOUR_ID
|
|
|
FROM prod_expert_sante.SEJOUR
|
|
|
WHERE SEJOUR_ID = SEJOUR.ID
|
|
|
;
|
|
|
|
|
|
|
|
|
-- commandes prothèses
|
|
|
DROP TABLE IF EXISTS w_PRODUIT_FACTURE;
|
|
|
CREATE TEMP TABLE w_PRODUIT_FACTURE AS
|
|
|
SELECT FACTURE_ID, PRODUIT_TYPE_ID, MIN(PRODUIT_ID) AS PRODUIT_ID
|
|
|
FROM prod_expert_sante.PRODUIT_FACTURE
|
|
|
GROUP BY 1,2
|
|
|
;
|
|
|
|
|
|
ANALYSE w_PRODUIT_FACTURE
|
|
|
;
|
|
|
|
|
|
CREATE INDEX w_PRODUIT_FACTURE_i1 ON w_PRODUIT_FACTURE USING BTREE (FACTURE_ID)
|
|
|
;
|
|
|
CREATE INDEX w_PRODUIT_FACTURE_i2 ON w_PRODUIT_FACTURE USING BTREE (PRODUIT_TYPE_ID)
|
|
|
;
|
|
|
|
|
|
INSERT INTO w_com
|
|
|
SELECT
|
|
|
COMMANDE.NUMERO::text || '-' || FACTURE.FOURNISSEUR_ID || '-' || PRODUIT_FACTURE.PRODUIT_TYPE_ID || '-' || PRODUIT_FACTURE.PRODUIT_ID AS code_original_ligne,
|
|
|
MAX(COMMANDE.NUMERO::text) AS COMMANDE_NUMERO,
|
|
|
MAX(COMMANDE.QUI),
|
|
|
MAX(COMMANDE.DATE_CREATION),
|
|
|
MAX(PRODUIT_FACTURE.PRODUIT_TYPE_ID),
|
|
|
MAX(PRODUIT_FACTURE.PRODUIT_ID) AS PRODUIT_ID,
|
|
|
MAX(FACTURE.FOURNISSEUR_ID),
|
|
|
COUNT(*) AS QUANTITE,
|
|
|
MAX(PRIX_UNITAIRE) AS PRIX_UNITAIRE,
|
|
|
0 AS STOCK_DESTINATAIRE_ID,
|
|
|
MAX(TVA)
|
|
|
FROM prod_expert_sante.COMMANDE
|
|
|
JOIN prod_expert_sante.FACTURE ON COMMANDE.NUMERO = COMMANDE_NUMERO
|
|
|
JOIN w_PRODUIT_FACTURE PRODUIT_FACTURE ON FACTURE_ID = FACTURE.ID
|
|
|
LEFT JOIN w_PRODUIT_TYPE_HISTO PRODUIT_TYPE_HISTO ON PRODUIT_TYPE_HISTO.PRODUIT_TYPE_ID = PRODUIT_FACTURE.PRODUIT_TYPE_ID AND DATE_CREATION BETWEEN DATE_EFFET AND COALESCE(DATE_FIN,'2099-12-31')
|
|
|
WHERE COMMANDE.DATE_CREATION >= '[ENV_ECO_ANNEEDEBUT]-01-01' AND
|
|
|
COMMANDE.NUMERO NOT IN (SELECT COMMANDE_NUMERO FROM w_com WHERE COMMANDE_NUMERO IS NOT NULL)
|
|
|
GROUP BY 1
|
|
|
;
|
|
|
|
|
|
--entrees = livraison
|
|
|
DROP TABLE IF EXISTS w_first_mvt;
|
|
|
CREATE TEMP TABLE w_first_mvt AS
|
|
|
SELECT
|
|
|
ID,
|
|
|
PRODUIT_TYPE_ID,
|
|
|
NUMERO,
|
|
|
MIN(DATE_RECEPTION) AS DATE_RECEPTION,
|
|
|
MIN(w_log_produit.code_original_cti) AS code_original_cti,
|
|
|
(MIN(ARRAY[code_original_cti::text, STOCK_ID::text]))[2]::bigint AS STOCK_ID,
|
|
|
(MIN(ARRAY[code_original_cti::text, UTILISATEUR_ID::text]))[2]::bigint AS UTILISATEUR_ID,
|
|
|
(MIN(ARRAY[code_original_cti::text, PRODUIT_FOURNISSEUR_ID::text]))[2]::bigint AS PRODUIT_FOURNISSEUR_ID,
|
|
|
MAX(EXTERNAL_SEJOUR_ID) AS EXTERNAL_SEJOUR_ID
|
|
|
FROM
|
|
|
w_log_produit
|
|
|
WHERE PRODUIT_TYPE_ETAT_ID = 3
|
|
|
GROUP BY 1,2,3
|
|
|
;
|
|
|
|
|
|
ANALYSE w_first_mvt
|
|
|
;
|
|
|
|
|
|
|
|
|
CREATE INDEX w_first_mvt_i1 ON w_first_mvt USING BTREE (NUMERO);
|
|
|
CREATE INDEX w_first_mvt_i2 ON w_first_mvt USING BTREE (PRODUIT_TYPE_ID);
|
|
|
|
|
|
DROP TABLE IF EXISTS w_liv;
|
|
|
CREATE TEMP TABLE w_liv AS
|
|
|
SELECT
|
|
|
COMMANDE.NUMERO,
|
|
|
w_first_mvt.PRODUIT_TYPE_ID,
|
|
|
MAX(w_first_mvt.DATE_RECEPTION) AS DATE_RECEPTION,
|
|
|
MAX(w_first_mvt.PRODUIT_FOURNISSEUR_ID) AS PRODUIT_FOURNISSEUR_ID, --peut être faux => non pris en compte
|
|
|
COUNT(DISTINCT ID) AS QUANTITE_LIVREE,
|
|
|
--MAX(PRIX_UNITAIRE) AS PRIX_UNITAIRE_LIVRE,
|
|
|
null::numeric AS PRIX_UNITAIRE_LIVRE
|
|
|
FROM prod_expert_sante.COMMANDE
|
|
|
LEFT JOIN w_first_mvt ON COMMANDE.NUMERO = w_first_mvt.NUMERO
|
|
|
WHERE COMMANDE.DATE_CREATION >= '[ENV_ECO_ANNEEDEBUT]-01-01'
|
|
|
GROUP BY 1,2
|
|
|
|
|
|
;
|
|
|
|
|
|
-- ajout des livraisons sans ligne de commande
|
|
|
INSERT INTO w_com
|
|
|
SELECT
|
|
|
w_com.COMMANDE_NUMERO::text || '-' || w_liv.PRODUIT_FOURNISSEUR_ID || '-' || w_liv.PRODUIT_TYPE_ID AS code_original_ligne,
|
|
|
w_com.COMMANDE_NUMERO,
|
|
|
w_com.QUI,
|
|
|
w_com.DATE_CREATION,
|
|
|
w_liv.PRODUIT_TYPE_ID,
|
|
|
0::bigint AS PRODUIT_ID,
|
|
|
MAX(w_liv.PRODUIT_FOURNISSEUR_ID) AS PRODUIT_FOURNISSEUR_ID,
|
|
|
SUM(QUANTITE_LIVREE) AS QUANTITE_LIVREE,
|
|
|
MAX(PRODUIT_TYPE_HISTO.PRIX_UNITAIRE) AS PRIX_UNITAIRE,
|
|
|
0 AS STOCK_DESTINATAIRE_ID,
|
|
|
MAX(PRODUIT_TYPE_HISTO.TVA) AS TVA
|
|
|
FROM w_liv
|
|
|
JOIN (SELECT COMMANDE_NUMERO, MAX(QUI) AS QUI, MAX(DATE_CREATION) AS DATE_CREATION FROM w_com GROUP BY 1) w_com ON NUMERO = COMMANDE_NUMERO
|
|
|
LEFT JOIN w_PRODUIT_TYPE_HISTO PRODUIT_TYPE_HISTO ON PRODUIT_TYPE_HISTO.PRODUIT_TYPE_ID = w_liv.PRODUIT_TYPE_ID AND DATE_RECEPTION BETWEEN DATE_EFFET AND COALESCE(DATE_FIN,'2099-12-31')
|
|
|
LEFT JOIN w_com ref ON NUMERO = ref.COMMANDE_NUMERO AND ref.PRODUIT_TYPE_ID = w_liv.PRODUIT_TYPE_ID
|
|
|
WHERE ref.COMMANDE_NUMERO IS NULL AND
|
|
|
QUANTITE_LIVREE <> 0
|
|
|
GROUP BY 1,2,3,4,5
|
|
|
;
|
|
|
|
|
|
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,
|
|
|
site_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
|
|
|
w_com.COMMANDE_NUMERO AS code_original,
|
|
|
w_com.COMMANDE_NUMERO AS numero,
|
|
|
w_com.DATE_CREATION::date AS date_commande,
|
|
|
date_trunc('month',w_com.DATE_CREATION::date) + interval '1 month' - interval '1 day' AS date_engagement,
|
|
|
'' AS objet,
|
|
|
'' AS reference,
|
|
|
'2099-12-31'::date AS date_livraison_prevue,
|
|
|
CASE WHEN SUM(QUANTITE_LIVREE) >= SUM(QUANTITE) THEN 'T'
|
|
|
WHEN SUM(QUANTITE_LIVREE) > 0 THEN 'P'
|
|
|
ELSE 'N' END AS etat_reception,
|
|
|
COALESCE(MAX(DATE_RECEPTION),'2099-12-31') AS date_reception,
|
|
|
CASE WHEN FACTURE.ID IS NOT NULL THEN 'T' ELSE 'N' 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,
|
|
|
COALESCE(t_gestionnaires.oid,0) AS gestionnaire_id,
|
|
|
MAX(COALESCE(t_sites.oid,0)),
|
|
|
MAX(COALESCE(t_lieux.oid,0)),
|
|
|
0 AS lieu_facturation_id,
|
|
|
MAX(COALESCE(t_sites.oid,0)),
|
|
|
MAX(COALESCE(t_unites_fonctionnelles.oid,0)),
|
|
|
SUM(QUANTITE*PRIX_UNITAIRE) AS montant_commande_ht,
|
|
|
0::numeric AS montant_commande_remise,
|
|
|
SUM(QUANTITE*PRIX_UNITAIRE*(TVA)/100) AS montant_commande_tva,
|
|
|
0::numeric AS montant_commande_port,
|
|
|
SUM(QUANTITE*PRIX_UNITAIRE*(100 + TVA)/100) AS montant_commande_total,
|
|
|
COALESCE(MAX(MONTANT_HT),0) AS montant_liquidation_ht,
|
|
|
0::numeric AS montant_liquidation_remise,
|
|
|
COALESCE(MAX(MONTANT_TTC - MONTANT_HT),0) AS montant_liquidation_tva,
|
|
|
0::numeric AS montant_liquidation_port,
|
|
|
COALESCE(MAX(MONTANT_TTC),0) AS montant_liquidation_total
|
|
|
FROM w_com
|
|
|
LEFT JOIN w_liv ON w_liv.NUMERO = w_com.COMMANDE_NUMERO::text AND w_liv.PRODUIT_TYPE_ID = w_com.PRODUIT_TYPE_ID AND w_liv.PRODUIT_FOURNISSEUR_ID = w_com.PRODUIT_FOURNISSEUR_ID
|
|
|
LEFT JOIN prod_expert_sante.FACTURE ON FACTURE.COMMANDE_NUMERO = w_com.COMMANDE_NUMERO::text
|
|
|
LEFT JOIN eco.t_fournisseurs ON w_com.PRODUIT_FOURNISSEUR_ID = t_fournisseurs.code_original
|
|
|
LEFT JOIN eco.t_gestionnaires ON w_com.QUI = t_gestionnaires.code_original
|
|
|
LEFT JOIN eco.t_lieux ON STOCK_DESTINATAIRE_ID = t_lieux.code_original
|
|
|
LEFT JOIN eco.t_sites ON 'XX' = t_lieux.code_original
|
|
|
LEFT JOIN prod_expert_sante.STOCK_SERVICE ON STOCK_DESTINATAIRE_ID = STOCK_ID
|
|
|
LEFT JOIN eco.t_unites_fonctionnelles ON SERVICE_ID = t_unites_fonctionnelles.code_original
|
|
|
GROUP BY 1,2,3,4,5,6,7,10,13
|
|
|
;
|
|
|
|
|
|
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,
|
|
|
unite_fonctionnelle_id,
|
|
|
article_id,
|
|
|
unite_approvisionnement_id,
|
|
|
lpp_id,
|
|
|
ucd_id,
|
|
|
compte_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_tva,
|
|
|
montant_livraison_ttc,
|
|
|
etat_livraison,
|
|
|
|
|
|
montant_liquidation_ht,
|
|
|
montant_liquidation_remise,
|
|
|
montant_liquidation_tva,
|
|
|
montant_liquidation_port,
|
|
|
montant_liquidation_ttc,
|
|
|
etat_liquidation,
|
|
|
|
|
|
taux_tva)
|
|
|
SELECT
|
|
|
code_original_ligne,
|
|
|
p_commandes.oid AS commande_id,
|
|
|
row_number() OVER (PARTITION BY COMMANDE_NUMERO ORDER BY w_com.PRODUIT_TYPE_ID, w_com.PRODUIT_ID) AS ligne_commande,
|
|
|
t_articles.texte_court AS texte,
|
|
|
p_commandes.fournisseur_distributeur_id,
|
|
|
COALESCE(t_unites_fonctionnelles.oid,0) AS unite_fonctionnelle_id,
|
|
|
COALESCE(t_articles.oid, 0) AS article_id,
|
|
|
COALESCE(t_unites.oid,t_articles.unite_stockage_id,0) AS unite_approvisionnement_id,
|
|
|
COALESCE(t_articles.lpp_id,0),
|
|
|
COALESCE(t_articles.ucd_id,0),
|
|
|
COALESCE(t_articles.compte_id, 0) AS compte_id,
|
|
|
QUANTITE AS quantite_approvisionnement,
|
|
|
PRIX_UNITAIRE AS prix_unitaire_approvisionnement,
|
|
|
1 AS multiplicateur_stockage,
|
|
|
1 AS quantite_stockage,
|
|
|
PRIX_UNITAIRE AS prix_unitaire_stockage,
|
|
|
|
|
|
QUANTITE * PRIX_UNITAIRE AS montant_commande_ht,
|
|
|
0 AS montant_commande_remise,
|
|
|
QUANTITE * PRIX_UNITAIRE * TVA/100 AS montant_commande_tva,
|
|
|
0 AS montant_commande_port,
|
|
|
QUANTITE * PRIX_UNITAIRE * (100 + TVA)/100 AS montant_commande_ttc,
|
|
|
|
|
|
QUANTITE_LIVREE AS quantite_livraison_approvisionnement,
|
|
|
QUANTITE_LIVREE AS quantite_livraison_stockage,
|
|
|
QUANTITE_LIVREE * COALESCE(PRIX_UNITAIRE_LIVRE,PRIX_UNITAIRE) AS montant_livraison_ht,
|
|
|
QUANTITE_LIVREE * COALESCE(PRIX_UNITAIRE_LIVRE,PRIX_UNITAIRE)*TVA/100 AS montant_livraison_tva,
|
|
|
QUANTITE_LIVREE * COALESCE(PRIX_UNITAIRE_LIVRE,PRIX_UNITAIRE) * (100 + TVA)/100 AS montant_livraison_ttc,
|
|
|
CASE
|
|
|
WHEN w_liv.DATE_RECEPTION IS NULL THEN 'N'
|
|
|
WHEN QUANTITE_LIVREE = QUANTITE THEN 'T'
|
|
|
WHEN QUANTITE_LIVREE > QUANTITE THEN 'S'
|
|
|
WHEN QUANTITE_LIVREE = 0 THEN 'N'
|
|
|
ELSE 'P' END AS etat_livraison,
|
|
|
0 AS montant_liquidation_ht,
|
|
|
0 AS montant_liquidation_remise,
|
|
|
0 AS montant_liquidation_tva,
|
|
|
0 AS montant_liquidation_port,
|
|
|
0 AS montant_liquidation_ttc,
|
|
|
p_commandes.etat_liquidation AS etat_liquidation,
|
|
|
TVA
|
|
|
FROM w_com
|
|
|
LEFT JOIN w_liv ON w_liv.NUMERO = w_com.COMMANDE_NUMERO::text AND w_liv.PRODUIT_TYPE_ID = w_com.PRODUIT_TYPE_ID
|
|
|
JOIN eco.p_commandes ON w_com.COMMANDE_NUMERO = p_commandes.code_original
|
|
|
LEFT JOIN eco.t_articles ON w_com.PRODUIT_TYPE_ID = t_articles.code_original
|
|
|
LEFT JOIN eco.t_unites ON 'XXX' = t_unites.code_original AND t_unites.oid <> 0
|
|
|
LEFT JOIN eco.t_gestionnaires ON w_com.QUI = t_gestionnaires.code_original
|
|
|
LEFT JOIN eco.t_lieux ON STOCK_DESTINATAIRE_ID = t_lieux.code_original
|
|
|
LEFT JOIN prod_expert_sante.STOCK_SERVICE ON STOCK_DESTINATAIRE_ID = STOCK_ID AND STOCK_SERVICE.REFERENCE = 1
|
|
|
LEFT JOIN eco.t_unites_fonctionnelles ON SERVICE_ID = t_unites_fonctionnelles.code_original
|
|
|
LEFT JOIN prod_expert_sante.SERVICE ON SERVICE.ID = SERVICE_ID
|
|
|
LEFT JOIN eco.t_sites ON ETAGE_ID = t_sites.code_original
|
|
|
|
|
|
;
|
|
|
|
|
|
UPDATE eco.p_lignes_commandes
|
|
|
SET
|
|
|
montant_liquidation_ht = montant_livraison_ht,
|
|
|
montant_liquidation_tva = montant_livraison_tva,
|
|
|
montant_liquidation_ttc = montant_livraison_ttc
|
|
|
WHERE etat_liquidation = 'T'
|
|
|
;
|
|
|
|
|
|
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="Mouvements">
|
|
|
<sqlcmd><![CDATA[
|
|
|
|
|
|
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');
|
|
|
|
|
|
--entrees = livraison
|
|
|
|
|
|
DROP TABLE IF EXISTS w_mvt;
|
|
|
CREATE TEMP TABLE w_mvt AS
|
|
|
SELECT
|
|
|
NUMERO || '-' || PRODUIT_FOURNISSEUR_ID || '-' || w_first_mvt.PRODUIT_TYPE_ID ID_CTI,
|
|
|
NUMERO || '-' || PRODUIT_FOURNISSEUR_ID || '-' || w_first_mvt.PRODUIT_TYPE_ID AS REF,
|
|
|
'LIV' AS TYPE ,
|
|
|
'E' AS sens,
|
|
|
w_first_mvt.PRODUIT_TYPE_ID,
|
|
|
w_first_mvt.UTILISATEUR_ID AS QUI,
|
|
|
w_first_mvt.STOCK_ID,
|
|
|
DATE_RECEPTION AS DATE,
|
|
|
PRODUIT_TYPE_HISTO.PRIX_UNITAIRE,
|
|
|
TVA,
|
|
|
COUNT(DISTINCT ID) AS QUANTITE,
|
|
|
COALESCE(EXTERNAL_SEJOUR_ID,'') AS SEJOUR,
|
|
|
MIN(w_first_mvt.code_original_cti) AS code_original_cti
|
|
|
FROM
|
|
|
w_first_mvt
|
|
|
JOIN w_PRODUIT_TYPE_HISTO PRODUIT_TYPE_HISTO ON w_first_mvt.PRODUIT_TYPE_ID = PRODUIT_TYPE_HISTO.PRODUIT_TYPE_ID AND DATE_RECEPTIOn BETWEEN DATE_EFFET AND COALESCE(DATE_FIN,'2099-12-31')
|
|
|
GROUP BY 1,2,3,4,5,6,7,8,9,10,12
|
|
|
;
|
|
|
|
|
|
--entree neg = retour fournisseur
|
|
|
DROP TABLE IF EXISTS w_PRODUIT_RETOUR;
|
|
|
CREATE TEMP TABLE w_PRODUIT_RETOUR AS
|
|
|
SELECT
|
|
|
PRODUIT_RETOUR.ID AS PRODUIT_RETOUR_ID,
|
|
|
PRODUIT_RETOUR.NUMERO AS PRODUIT_RETOUR_NUMERO,
|
|
|
PRODUIT.PRODUIT_TYPE_ID,
|
|
|
PRODUIT_RETOUR.QUI AS PRODUIT_RETOUR_QUI,
|
|
|
STOCK_ID,
|
|
|
PRODUIT_RETOUR.DATE_CREATION AS PRODUIT_RETOUR_DATE_CREATION,
|
|
|
PRODUIT_TYPE_HISTO.PRIX_UNITAIRE,
|
|
|
TVA,
|
|
|
EXEMPLAIRE,
|
|
|
PRODUIT_RETOUR.ID::text||'-'||row_number() OVER (PARTITION BY PRODUIT_RETOUR.ID ORDER BY PRODUIT_RETOUR.DATE_CREATION, PRODUIT.PRODUIT_TYPE_ID, STOCK_ID) AS code_original_cti
|
|
|
FROM
|
|
|
prod_expert_sante.PRODUIT_RETOUR
|
|
|
JOIN prod_expert_sante.PRODUIT_RETOUR_PRODUIT ON PRODUIT_RETOUR_ID = PRODUIT_RETOUR.ID
|
|
|
JOIN prod_expert_sante.PRODUIT ON PRODUIT_ID = PRODUIT.ID
|
|
|
JOIN w_PRODUIT_TYPE_HISTO PRODUIT_TYPE_HISTO ON PRODUIT_TYPE_HISTO.PRODUIT_TYPE_ID = PRODUIT.PRODUIT_TYPE_ID AND DATE_RECEPTION BETWEEN DATE_EFFET AND COALESCE(DATE_FIN,'2099-12-31')
|
|
|
WHERE PRODUIT_RETOUR.DATE_CREATION >= '[ENV_ECO_ANNEEDEBUT]-01-01'
|
|
|
;
|
|
|
|
|
|
INSERT INTO w_mvt
|
|
|
SELECT
|
|
|
PRODUIT_RETOUR_ID || '-' || PRODUIT_TYPE_ID,
|
|
|
PRODUIT_RETOUR_NUMERO || '-' || PRODUIT_TYPE_ID,
|
|
|
'RET_F',
|
|
|
'E' AS sens,
|
|
|
PRODUIT_TYPE_ID,
|
|
|
PRODUIT_RETOUR_QUI,
|
|
|
STOCK_ID,
|
|
|
PRODUIT_RETOUR_DATE_CREATION,
|
|
|
PRIX_UNITAIRE,
|
|
|
TVA,
|
|
|
-COUNT(DISTINCT PRODUIT_RETOUR_ID) AS QUANTITE,
|
|
|
'' AS SEJOUR,
|
|
|
MIN(code_original_cti) AS code_original_cti
|
|
|
FROM w_PRODUIT_RETOUR
|
|
|
GROUP BY 1,2,3,4,5,6,7,8,9,10
|
|
|
;
|
|
|
|
|
|
DROP TABLE IF EXISTS w_mvt_log;
|
|
|
create temp table w_mvt_log AS
|
|
|
SELECT
|
|
|
sub.PRODUIT_TYPE_ID,
|
|
|
STOCK.FINAL AS FROM_FINAL,
|
|
|
DEST.FINAL AS TO_FINAL,
|
|
|
STOCK.ID AS FROM_STOCK,
|
|
|
DEST.ID AS TO_STOCK,
|
|
|
sub.UTILISATEUR_ID,
|
|
|
date_trunc('day',sub.QUAND) AS QUAND,
|
|
|
COALESCE(EXTERNAL_SEJOUR_ID,'') AS EXTERNAL_SEJOUR_ID,
|
|
|
COUNT(DISTINCT sub.ID) AS QUANTITE,
|
|
|
MIN(code_original_cti) AS code_original_cti
|
|
|
FROM (
|
|
|
SELECT
|
|
|
code_original_cti,
|
|
|
ID,
|
|
|
PRODUIT_TYPE_ID,
|
|
|
EXEMPLAIRE,
|
|
|
UTILISATEUR_ID,
|
|
|
QUAND,
|
|
|
code_original_cti AS ctid_to,
|
|
|
lag(ctid) OVER (PARTITION BY PRODUIT_TYPE_ID,ID,NUMERO ORDER BY ctid) AS ctid_from,
|
|
|
STOCK_ID,
|
|
|
lag(STOCK_ID) OVER (PARTITION BY PRODUIT_TYPE_ID,ID,NUMERO ORDER BY ctid) AS stock_id_from,
|
|
|
COALESCE(EXTERNAL_SEJOUR_ID,'') AS EXTERNAL_SEJOUR_ID
|
|
|
FROM w_LOG_PRODUIT
|
|
|
WHERE PRODUIT_TYPE_ETAT_ID = 3
|
|
|
AND STOCK_ID IS NOT NULL
|
|
|
) sub
|
|
|
JOIN prod_expert_sante.STOCK ON stock_id_from IS NOT NULL AND stock_id_from = STOCK.ID
|
|
|
JOIN prod_expert_sante.STOCK DEST ON STOCK_ID = DEST.ID
|
|
|
WHERE stock_id_from != STOCK_ID
|
|
|
GROUP BY 1,2,3,4,5,6,7,8;
|
|
|
|
|
|
INSERT INTO w_mvt
|
|
|
SELECT
|
|
|
w_mvt_log.PRODUIT_TYPE_ID || '-' || FROM_STOCK || '-' || TO_STOCK || '-' || to_char(QUAND, 'YYYYMMDD'),
|
|
|
w_mvt_log.PRODUIT_TYPE_ID || '-' || FROM_STOCK || '-' || TO_STOCK || '-' || to_char(QUAND, 'YYYYMMDD'),
|
|
|
CASE WHEN FROM_FINAL = 0 AND TO_FINAL = 1 THEN 'SOR_C'
|
|
|
WHEN FROM_FINAL = 0 AND TO_FINAL = 0 THEN 'TRS'
|
|
|
ELSE 'DIS' END,
|
|
|
CASE WHEN FROM_FINAL = 0 AND TO_FINAL = 1 THEN 'S'
|
|
|
WHEN FROM_FINAL = 0 AND TO_FINAL = 0 THEN 'S'
|
|
|
ELSE 'E' END,
|
|
|
w_mvt_log.PRODUIT_TYPE_ID,
|
|
|
UTILISATEUR_ID,
|
|
|
CASE WHEN FROM_FINAL = 0 THEN FROM_STOCK ELSE TO_STOCK END,
|
|
|
QUAND,
|
|
|
PRIX_UNITAIRE,
|
|
|
TVA,
|
|
|
QUANTITE,
|
|
|
EXTERNAL_SEJOUR_ID,
|
|
|
w_mvt_log.code_original_cti ||
|
|
|
CASE WHEN FROM_FINAL = 0 AND TO_FINAL = 1 THEN ''
|
|
|
WHEN FROM_FINAL = 0 AND TO_FINAL = 0 THEN 'S'
|
|
|
ELSE '' END
|
|
|
FROM w_mvt_log
|
|
|
JOIN w_PRODUIT_TYPE_HISTO PRODUIT_TYPE_HISTO ON PRODUIT_TYPE_HISTO.PRODUIT_TYPE_ID = w_mvt_log.PRODUIT_TYPE_ID AND w_mvt_log.QUAND BETWEEN DATE_EFFET AND DATE_FIN
|
|
|
WHERE QUAND >= '[ENV_ECO_ANNEEDEBUT]-01-01'
|
|
|
AND NOT (FROM_FINAL = 1 AND TO_FINAL = 1)
|
|
|
;
|
|
|
|
|
|
INSERT INTO w_mvt
|
|
|
SELECT
|
|
|
w_mvt_log.PRODUIT_TYPE_ID || '-' || FROM_STOCK || '-' || TO_STOCK || '-' || to_char(QUAND, 'YYYYMMDD') ,
|
|
|
w_mvt_log.PRODUIT_TYPE_ID || '-' || FROM_STOCK || '-' || TO_STOCK || '-' || to_char(QUAND, 'YYYYMMDD') ,
|
|
|
'TRS',
|
|
|
'E',
|
|
|
w_mvt_log.PRODUIT_TYPE_ID,
|
|
|
UTILISATEUR_ID,
|
|
|
TO_STOCK,
|
|
|
QUAND,
|
|
|
PRIX_UNITAIRE,
|
|
|
TVA,
|
|
|
QUANTITE,
|
|
|
EXTERNAL_SEJOUR_ID,
|
|
|
w_mvt_log.code_original_cti || 'E'
|
|
|
FROM w_mvt_log
|
|
|
JOIN w_PRODUIT_TYPE_HISTO PRODUIT_TYPE_HISTO ON PRODUIT_TYPE_HISTO.PRODUIT_TYPE_ID = w_mvt_log.PRODUIT_TYPE_ID AND w_mvt_log.QUAND BETWEEN DATE_EFFET AND DATE_FIN
|
|
|
WHERE QUAND >= '[ENV_ECO_ANNEEDEBUT]-01-01'
|
|
|
AND FROM_FINAL = 0
|
|
|
AND TO_FINAL = 0
|
|
|
;
|
|
|
|
|
|
-- utilisation
|
|
|
INSERT INTO w_mvt
|
|
|
SELECT
|
|
|
w_log_produit.PRODUIT_TYPE_ID || '-P-' || STOCK_ID AS ID_CTI,
|
|
|
w_log_produit.PRODUIT_TYPE_ID || '-' || PRODUIT_FOURNISSEUR_ID || '-' || w_log_produit.PRODUIT_TYPE_ID AS REF,
|
|
|
'SOR_C' as type,
|
|
|
'S' as sens,
|
|
|
w_log_produit.PRODUIT_TYPE_ID,
|
|
|
UTILISATEUR_ID,
|
|
|
w_log_produit.STOCK_ID,
|
|
|
QUAND as date,
|
|
|
PRIX_UNITAIRE,
|
|
|
TVA,
|
|
|
COUNT(DISTINCT w_log_produit.id) as count,
|
|
|
EXTERNAL_SEJOUR_ID,
|
|
|
min(code_original_cti) AS code_original_cti
|
|
|
FROM (
|
|
|
SELECT ID, MIN(code_original_cti) as first
|
|
|
FROM w_log_produit
|
|
|
WHERE PRODUIT_TYPE_ETAT_ID = 4
|
|
|
GROUP BY 1) sub
|
|
|
JOIN w_log_produit on first = code_original_cti
|
|
|
JOIN w_PRODUIT_TYPE_HISTO PRODUIT_TYPE_HISTO ON PRODUIT_TYPE_HISTO.PRODUIT_TYPE_ID = w_log_produit.PRODUIT_TYPE_ID AND w_log_produit.QUAND BETWEEN DATE_EFFET AND DATE_FIN
|
|
|
WHERE w_log_produit.QUAND >= '[ENV_ECO_ANNEEDEBUT]-01-01'
|
|
|
GROUP BY 1,2,3,4,5,6,7,8,9,10,12
|
|
|
;
|
|
|
|
|
|
-- pertes (pour les non utilisés)
|
|
|
INSERT INTO w_mvt
|
|
|
SELECT
|
|
|
w_log_produit.PRODUIT_TYPE_ID || '-P-' || STOCK_ID AS ID_CTI,
|
|
|
w_log_produit.PRODUIT_TYPE_ID || '-' || PRODUIT_FOURNISSEUR_ID || '-' || w_log_produit.PRODUIT_TYPE_ID AS REF,
|
|
|
'PER',
|
|
|
'S',
|
|
|
w_log_produit.PRODUIT_TYPE_ID,
|
|
|
UTILISATEUR_ID,
|
|
|
w_log_produit.STOCK_ID,
|
|
|
MIN(QUAND),
|
|
|
PRIX_UNITAIRE,
|
|
|
TVA,
|
|
|
COUNT(DISTINCT w_log_produit.ID),
|
|
|
EXTERNAL_SEJOUR_ID,
|
|
|
min(code_original_cti) AS code_original_cti
|
|
|
FROM w_log_produit
|
|
|
JOIN w_PRODUIT_TYPE_HISTO PRODUIT_TYPE_HISTO ON PRODUIT_TYPE_HISTO.PRODUIT_TYPE_ID = w_log_produit.PRODUIT_TYPE_ID AND w_log_produit.QUAND BETWEEN DATE_EFFET AND DATE_FIN
|
|
|
LEFT JOIN (
|
|
|
SELECT ID
|
|
|
FROM w_log_produit
|
|
|
WHERE PRODUIT_TYPE_ETAT_ID = 4
|
|
|
GROUP BY 1) util ON util.ID = w_log_produit.ID
|
|
|
WHERE w_log_produit.QUAND >= '[ENV_ECO_ANNEEDEBUT]-01-01'
|
|
|
AND util.ID IS NULL
|
|
|
AND PRODUIT_TYPE_ETAT_ID = 11
|
|
|
GROUP BY 1,2,3,4,5,6,7,9,10,12
|
|
|
;
|
|
|
|
|
|
-- corrections inventaire (si non passé en perte)
|
|
|
/* INSERT INTO w_mvt
|
|
|
SELECT
|
|
|
INVENTAIRE_ID || '-' || INVENTAIRE_PRODUIT_TYPE_QTE.PRODUIT_TYPE_ID || '-' || 'I',
|
|
|
INVENTAIRE_ID || '-' || INVENTAIRE_PRODUIT_TYPE_QTE.PRODUIT_TYPE_ID || '-' || 'I',
|
|
|
'INV',
|
|
|
'S',
|
|
|
INVENTAIRE_PRODUIT_TYPE_QTE.PRODUIT_TYPE_ID,
|
|
|
UTILISATEUR_ID,
|
|
|
INVENTAIRE_PRODUIT_TYPE_QTE.STOCK_ID,
|
|
|
DATE_VALIDATION,
|
|
|
PUHT,
|
|
|
TVA,
|
|
|
QTE_ATTENDUE - QTE_SAISIE,
|
|
|
'' AS no_sejour,
|
|
|
INVENTAIRE_PRODUIT_TYPE_QTE.ID::text AS code_original_cti
|
|
|
FROM prod_expert_sante.INVENTAIRE
|
|
|
JOIN prod_expert_sante.INVENTAIRE_PRODUIT_TYPE_QTE ON INVENTAIRE_ID = INVENTAIRE.ID
|
|
|
JOIN w_PRODUIT_TYPE_HISTO PRODUIT_TYPE_HISTO ON PRODUIT_TYPE_HISTO.PRODUIT_TYPE_ID = INVENTAIRE_PRODUIT_TYPE_QTE.PRODUIT_TYPE_ID AND DATE_VALIDATION BETWEEN DATE_EFFET AND COALESCE(DATE_FIN,'2099-12-31')
|
|
|
WHERE DATE_VALIDATION >= '[ENV_ECO_ANNEEDEBUT]-01-01'
|
|
|
AND INVENTAIRE.VALIDER = '1'
|
|
|
AND QTE_ATTENDUE != QTE_SAISIE
|
|
|
;*/
|
|
|
|
|
|
|
|
|
INSERT INTO w_mvt
|
|
|
SELECT
|
|
|
w_first_mvt.NUMERO || '-' || PRODUIT_FOURNISSEUR_ID || '-' || w_first_mvt.PRODUIT_TYPE_ID ID_CTI,
|
|
|
w_first_mvt.NUMERO || '-' || PRODUIT_FOURNISSEUR_ID || '-' || w_first_mvt.PRODUIT_TYPE_ID AS REF,
|
|
|
'SOR_D' AS TYPE ,
|
|
|
'S' AS sens,
|
|
|
w_first_mvt.PRODUIT_TYPE_ID,
|
|
|
w_first_mvt.UTILISATEUR_ID AS QUI,
|
|
|
w_first_mvt.STOCK_ID,
|
|
|
DATE_RECEPTION AS DATE,
|
|
|
PRODUIT_TYPE_HISTO.PRIX_UNITAIRE,
|
|
|
TVA,
|
|
|
COUNT(DISTINCT w_first_mvt.ID) AS QUANTITE,
|
|
|
EXTERNAL_SEJOUR_ID AS SEJOUR,
|
|
|
MIN(w_first_mvt.code_original_cti) || '-SD' AS code_original_cti
|
|
|
FROM
|
|
|
w_first_mvt
|
|
|
LEFT JOIN (SELECT ID FROM w_log_produit WHERE PRODUIT_TYPE_ETAT_ID = 4) sub ON sub.ID = w_first_mvt.ID
|
|
|
JOIN prod_expert_sante.STOCK ON STOCK_ID = STOCK.ID
|
|
|
JOIN w_PRODUIT_TYPE_HISTO PRODUIT_TYPE_HISTO ON w_first_mvt.PRODUIT_TYPE_ID = PRODUIT_TYPE_HISTO.PRODUIT_TYPE_ID AND DATE_RECEPTIOn BETWEEN DATE_EFFET AND COALESCE(DATE_FIN,'2099-12-31')
|
|
|
WHERE FINAL = '1' AND sub.ID IS NULL
|
|
|
GROUP BY 1,2,3,4,5,6,7,8,9,10,12
|
|
|
;
|
|
|
|
|
|
CREATE INDEX w_mvt_stock_id ON w_mvt USING btree (stock_id);
|
|
|
CREATE INDEX w_mvt_produit_type_id ON w_mvt USING btree (produit_type_id);
|
|
|
CREATE INDEX w_mvt_stock_date ON w_mvt USING btree (date);
|
|
|
|
|
|
|
|
|
TRUNCATE eco.p_mouvements_articles;
|
|
|
|
|
|
INSERT INTO eco.p_mouvements_articles(
|
|
|
code_original,
|
|
|
date,
|
|
|
sens_mouvement,
|
|
|
type_mouvement_id,
|
|
|
texte,
|
|
|
gestionnaire_id,
|
|
|
site_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,
|
|
|
prix_unitaire_calcule,
|
|
|
stock_quantite_debut,
|
|
|
stock_quantite_fin,
|
|
|
date_fin,
|
|
|
est_premier_jour,
|
|
|
est_dernier_jour,
|
|
|
no_sejour
|
|
|
)
|
|
|
SELECT
|
|
|
w_mvt.TYPE || '-' || w_mvt.code_original_cti AS code_original,
|
|
|
DATE,
|
|
|
sens AS sens_mouvement,
|
|
|
COALESCE(t_types_mouvements.oid,0) AS type_mouvement_id,
|
|
|
COALESCE(LEFT(t_types_mouvements.texte || ' ' || t_articles.texte,255),'0') AS texte,
|
|
|
COALESCE(t_gestionnaires.oid,0) AS gestionnaire_id,
|
|
|
COALESCE(t_sites.oid,0) AS site_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_articles.compte_id,0) AS compte_id,
|
|
|
COALESCE(t_fournisseurs.oid,0) AS fournisseur_id,
|
|
|
COALESCE(commande_id, 0) AS commande_id,
|
|
|
COALESCE(ligne_commande, 0) AS ligne_commande,
|
|
|
COALESCE(t_articles.ucd_id,0),
|
|
|
COALESCE(t_articles.lpp_id,0),
|
|
|
PRIX_UNITAIRE,
|
|
|
CASE WHEN sens = 'E' THEN QUANTITE ELSE 0 END AS entree_quantite,
|
|
|
CASE WHEN sens = 'S' THEN QUANTITE ELSE 0 END AS sortie_quantite,
|
|
|
CASE WHEN sens = 'E' THEN QUANTITE * PRIX_UNITAIRE * (100 + TVA ) / 100 ELSE 0 END AS entree_montant,
|
|
|
CASE WHEN sens = 'E' THEN QUANTITE * PRIX_UNITAIRE ELSE 0 END AS entree_montant_ht,
|
|
|
CASE WHEN sens = 'S' THEN QUANTITE * PRIX_UNITAIRE * (100 + TVA ) / 100 ELSE 0 END AS sortie_montant,
|
|
|
CASE WHEN sens = 'S' THEN QUANTITE * PRIX_UNITAIRE ELSE 0 END AS sortie_montant_ht,
|
|
|
CASE WHEN sens = 'S' THEN QUANTITE * PRIX_UNITAIRE * (100 + TVA ) / 100 ELSE 0 END AS sortie_montant_original_ttc,
|
|
|
CASE WHEN sens = 'S' THEN QUANTITE * PRIX_UNITAIRE ELSE 0 END AS sortie_montant_original_ht,
|
|
|
PRIX_UNITAIRE AS prix_unitaire_calcule,
|
|
|
0,
|
|
|
0,
|
|
|
CASE
|
|
|
WHEN COALESCE(LEAD(DATE) OVER (PARTITION BY PRODUIT_TYPE_ID, w_mvt.STOCK_ID ORDER BY DATE),'2100-01-01') = DATE THEN
|
|
|
DATE
|
|
|
ELSE COALESCE(LEAD(DATE) OVER (PARTITION BY PRODUIT_TYPE_ID, w_mvt.STOCK_ID ORDER BY DATE),'2100-01-01') - interval '1 day'
|
|
|
END as date_fin,
|
|
|
CASE WHEN rank() OVER (PARTITION BY PRODUIT_TYPE_ID, w_mvt.STOCK_ID, date_trunc('day',DATE) ORDER BY DATE) = 1 THEN 1
|
|
|
ELSE 0
|
|
|
END AS est_premier_jour,
|
|
|
CASE
|
|
|
WHEN cume_dist() OVER (PARTITION BY PRODUIT_TYPE_ID, w_mvt.STOCK_ID, date_trunc('day',DATE) ORDER BY DATE) = 1 THEN 1
|
|
|
ELSE 0
|
|
|
END AS est_dernier_jour,
|
|
|
w_mvt.SEJOUR AS no_sejour
|
|
|
FROM w_mvt
|
|
|
LEFT JOIN eco.t_types_mouvements ON TYPE = t_types_mouvements.code
|
|
|
LEFT JOIN eco.t_articles ON PRODUIT_TYPE_ID = t_articles.code_original AND t_articles.oid <> 0
|
|
|
LEFT JOIN eco.t_gestionnaires ON QUI = t_gestionnaires.code_original
|
|
|
LEFT JOIN eco.t_lieux ON STOCK_ID = t_lieux.code_original
|
|
|
LEFT JOIN prod_expert_sante.STOCK_SERVICE ON STOCK_SERVICE.STOCK_ID = w_mvt.STOCK_ID
|
|
|
LEFT JOIN eco.t_unites_fonctionnelles ON t_unites_fonctionnelles.code_original = SERVICE_ID
|
|
|
LEFT JOIN prod_expert_sante.SERVICE ON SERVICE.ID = SERVICE_ID
|
|
|
LEFT JOIN eco.t_sites ON ETAGE_ID = t_sites.code_original
|
|
|
LEFT JOIN eco.t_fournisseurs ON 0 = t_fournisseurs.code_original
|
|
|
LEFT JOIN eco.p_lignes_commandes ON REF = p_lignes_commandes.code_original
|
|
|
WHERE DATE >= '[ENV_ECO_ANNEEDEBUT]0101' ;
|
|
|
|
|
|
|
|
|
UPDATE eco.p_mouvements_articles SET
|
|
|
entree_quantite = 0 - entree_quantite,
|
|
|
sortie_quantite = 0 - sortie_quantite,
|
|
|
entree_montant = 0 - entree_montant,
|
|
|
sortie_montant = 0 - sortie_montant,
|
|
|
entree_montant_ht = 0 - entree_montant_ht,
|
|
|
sortie_montant_ht = 0 - sortie_montant_ht,
|
|
|
sortie_montant_original_ttc = 0 - sortie_montant_original_ttc,
|
|
|
sortie_montant_original_ht = 0 - sortie_montant_original_ht
|
|
|
FROM eco.t_types_mouvements
|
|
|
WHERE type_mouvement_id = t_types_mouvements.oid AND
|
|
|
t_types_mouvements.particularite_inverser_signe = '1';
|
|
|
|
|
|
UPDATE eco.p_mouvements_articles SET
|
|
|
entree_quantite = sortie_quantite,
|
|
|
sortie_quantite = entree_quantite,
|
|
|
entree_montant = sortie_montant,
|
|
|
sortie_montant = entree_montant,
|
|
|
entree_montant_ht = sortie_montant_ht,
|
|
|
sortie_montant_ht = entree_montant_ht,
|
|
|
sortie_montant_original_ttc = sortie_montant_original_ht,
|
|
|
sortie_montant_original_ht = sortie_montant_original_ttc,
|
|
|
sens_mouvement = sens_force
|
|
|
FROM eco.t_types_mouvements
|
|
|
WHERE type_mouvement_id = t_types_mouvements.oid AND
|
|
|
t_types_mouvements.sens_force IN ('E','S') AND t_types_mouvements.sens_force != p_mouvements_articles.sens_mouvement
|
|
|
;
|
|
|
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');
|
|
|
|
|
|
VACUUM ANALYSE eco.p_mouvements_articles;
|
|
|
|
|
|
|
|
|
|
|
|
]]></sqlcmd>
|
|
|
</NODE>
|
|
|
|
|
|
<NODE label="Stocks">
|
|
|
<sqlcmd><![CDATA[
|
|
|
|
|
|
|
|
|
|
|
|
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');
|
|
|
|
|
|
|
|
|
DROP TABLE IF EXISTS w_stock_inv;
|
|
|
CREATE TEMP TABLE w_stock_inv AS
|
|
|
SELECT
|
|
|
PRODUIT_TYPE_ID,
|
|
|
STOCK_ID,
|
|
|
DATE_TRUNC('month',DATE_DEBUT) AS DATE_DEBUT,
|
|
|
MAX(DATE_DEBUT) AS DATE_VALIDATION,
|
|
|
MIN(DATE_DEBUT) AS DATE_VALIDATION_DEBUT,
|
|
|
(MAX(ARRAY[COALESCE(DATE_DEBUT)::text,QTE_SAISIE::text]))[2]::numeric AS QTE_SAISIE,
|
|
|
(MIN(ARRAY[COALESCE(DATE_DEBUT)::text,QTE_SAISIE::text]))[2]::numeric AS QTE_SAISIE_DEBUT,
|
|
|
AVG(PUHT) AS PUHT,
|
|
|
(MAX(ARRAY[DATE_DEBUT::text,UTILISATEUR_ID::text]))[2]::numeric AS UTILISATEUR_ID
|
|
|
FROM
|
|
|
(
|
|
|
SELECT
|
|
|
INVENTAIRE.ID,
|
|
|
INVENTAIRE_PRODUIT_TYPE_QTE.STOCK_ID,
|
|
|
PRODUIT_TYPE_ID,
|
|
|
COALESCE(DATE_VALIDATION,DATE_DEBUT) AS DATE_DEBUT,
|
|
|
SUM(CASE WHEN DATE_VALIDATION IS NOT NULL THEN QTE_SAISIE ELSE QTE_ATTENDUE END) AS QTE_SAISIE,
|
|
|
AVG(PUHT) AS PUHT,
|
|
|
MAX(UTILISATEUR_ID) AS UTILISATEUR_ID
|
|
|
FROM prod_expert_sante.INVENTAIRE
|
|
|
JOIN prod_expert_sante.INVENTAIRE_PRODUIT_TYPE_QTE ON INVENTAIRE_ID = INVENTAIRE.ID
|
|
|
GROUP BY 1,2,3,4
|
|
|
) sub
|
|
|
LEFT JOIN eco.t_articles ON PRODUIT_TYPE_ID = t_articles.code_original
|
|
|
WHERE DATE_DEBUT >= '[ENV_ECO_ANNEEDEBUT]-01-01'
|
|
|
GROUP BY 1,2,3
|
|
|
;
|
|
|
|
|
|
-- cumul ES d'après mouvements et inventaires
|
|
|
DROP SEQUENCE IF EXISTS w_etat_seq;
|
|
|
CREATE TEMP SEQUENCE w_etat_seq;
|
|
|
|
|
|
DROP TABLE IF EXISTS w_stock;
|
|
|
CREATE TEMP TABLE w_stock AS
|
|
|
SELECT subview.*, '20991231' ::date AS date_fin, nextval('w_etat_seq'::regclass) AS etat_sequence, 0 AS orig
|
|
|
FROM (
|
|
|
SELECT
|
|
|
w_stock_inv.STOCK_ID,
|
|
|
w_stock_inv.PRODUIT_TYPE_ID,
|
|
|
date_trunc('month', DATE_VALIDATION) AS date_debut,
|
|
|
SUM(COALESCE(CASE WHEN w_mvt.SENS = 'E' THEN QUANTITE ELSE 0 END,0)) AS entree_quantite,
|
|
|
SUM(COALESCE(CASE WHEN w_mvt.SENS = 'E' THEN QUANTITE ELSE 0 END * PRIX_UNITAIRE,0)) AS entree_montant,
|
|
|
SUM(COALESCE(CASE WHEN w_mvt.SENS = 'S' THEN QUANTITE ELSE 0 END,0)) AS sortie_quantite,
|
|
|
SUM(COALESCE(CASE WHEN w_mvt.SENS = 'S' THEN QUANTITE ELSE 0 END * PRIX_UNITAIRE,0)) AS sortie_montant,
|
|
|
COALESCE((MAX(ARRAY[DATE::text,PRIX_UNITAIRE::text]))[2]::numeric,PUHT) as PRIX_UNITAIRE,
|
|
|
QTE_SAISIE_DEBUT +
|
|
|
SUM(CASE WHEN w_mvt.DATE IS NOT NULL AND w_mvt.DATE <= DATE_VALIDATION_DEBUT THEN
|
|
|
CASE WHEN w_mvt.sens = 'E' THEN -QUANTITE ELSE QUANTITE END
|
|
|
ELSE 0 END) AS stock_quantite_debut,
|
|
|
QTE_SAISIE +
|
|
|
SUM(CASE WHEN w_mvt.DATE IS NOT NULL AND w_mvt.DATE > DATE_VALIDATION THEN
|
|
|
CASE WHEN w_mvt.sens = 'E' THEN QUANTITE ELSE -QUANTITE END
|
|
|
ELSE 0 END) AS stock_quantite_fin,
|
|
|
(QTE_SAISIE * PUHT +
|
|
|
COALESCE(SUM(PRIX_UNITAIRE * CASE WHEN w_mvt.DATE IS NOT NULL AND w_mvt.DATE > DATE_VALIDATION THEN
|
|
|
CASE WHEN w_mvt.sens = 'E' THEN QUANTITE ELSE -QUANTITE END
|
|
|
ELSE 0 END),0))
|
|
|
AS stock_valeur_fin,
|
|
|
COALESCE(MAX(w_mvt.TVA),0) AS TVA
|
|
|
FROM
|
|
|
w_stock_inv
|
|
|
LEFT JOIN w_mvt ON w_mvt.STOCK_ID = w_stock_inv.STOCK_ID
|
|
|
AND w_mvt.PRODUIT_TYPE_ID = w_stock_inv.PRODUIT_TYPE_ID
|
|
|
AND date_trunc('month',w_mvt.DATE) = DATE_DEBUT
|
|
|
LEFT JOIN eco.t_lieux ON w_stock_inv.STOCK_ID = t_lieux.code_original
|
|
|
LEFT JOIN prod_expert_sante.STOCK_SERVICE ON w_stock_inv.STOCK_ID = STOCK_SERVICE.STOCK_ID
|
|
|
LEFT JOIN prod_expert_sante.SERVICE ON SERVICE.ID = SERVICE_ID
|
|
|
LEFT JOIN eco.t_sites ON ETAGE_ID = t_sites.code_original
|
|
|
GROUP BY 1,2,3,QTE_SAISIE,QTE_SAISIE_DEBUT,PUHT
|
|
|
) subview
|
|
|
ORDER BY 1,2,3
|
|
|
;
|
|
|
|
|
|
|
|
|
INSERT INTO w_stock
|
|
|
SELECT
|
|
|
cur.STOCK_ID,
|
|
|
cur.PRODUIT_TYPE_ID,
|
|
|
date_trunc('month', now()) AS date_debut,
|
|
|
COALESCE(SUM(CASE WHEN w_mvt.sens = 'E' THEN QUANTITE ELSE 0 END),0) AS entree_quantite,
|
|
|
COALESCE(SUM(CASE WHEN w_mvt.sens = 'E' THEN QUANTITE ELSE 0 END * w_mvt.PRIX_UNITAIRE),0) AS entree_montant,
|
|
|
COALESCE(SUM(CASE WHEN w_mvt.sens = 'S' THEN QUANTITE ELSE 0 END),0) AS sortie_quantite,
|
|
|
COALESCE(SUM(CASE WHEN w_mvt.sens = 'S' THEN QUANTITE ELSE 0 END * w_mvt.PRIX_UNITAIRE),0) AS sortie_montant,
|
|
|
cur.prix_unitaire,
|
|
|
qte_cur + COALESCE(SUM(CASE WHEN w_mvt.sens = 'E' THEN -QUANTITE ELSE QUANTITE END),0) AS stock_quantite_debut,
|
|
|
qte_cur AS stock_quantite_fin,
|
|
|
qte_cur * cur.prix_unitaire AS stock_valeur_fin,
|
|
|
0 AS TVA,
|
|
|
'20991231'::date AS date_fin,
|
|
|
nextval('w_etat_seq'::regclass) AS etat_sequence,
|
|
|
1 AS orig
|
|
|
FROM
|
|
|
(
|
|
|
SELECT stock_id, produit_type_id, (max(array[sub.id::text, prix_unitaire::text]))[2]::numeric AS prix_unitaire, count(distinct sub.id) AS qte_cur
|
|
|
FROM
|
|
|
(
|
|
|
SELECT
|
|
|
produit_type_id,
|
|
|
|
|
|
id,
|
|
|
(max(array[quand::text, stock_id::text]))[2]::numeric AS stock_id,
|
|
|
(max(array[quand::text, produit_type_etat_id::text]))[2]::numeric AS produit_type_etat_id,
|
|
|
(max(array[quand::text, prix_unitaire::text]))[2]::numeric AS prix_unitaire
|
|
|
FROM prod_expert_sante.produit
|
|
|
GROUP BY 1,2
|
|
|
) sub
|
|
|
JOIN prod_expert_sante.STOCK ON STOCK_ID = STOCK.ID
|
|
|
WHERE produit_type_etat_id = 3 AND final != 1
|
|
|
GROUP BY 1,2
|
|
|
) cur
|
|
|
LEFT JOIN w_mvt ON w_mvt.STOCK_ID = cur.STOCK_ID
|
|
|
AND w_mvt.PRODUIT_TYPE_ID = cur.PRODUIT_TYPE_ID
|
|
|
AND date_trunc('month',w_mvt.DATE) = date_trunc('month', now())
|
|
|
LEFT JOIN w_stock w_stock_check ON cur.STOCK_ID = w_stock_check.STOCK_ID
|
|
|
AND cur.PRODUIT_TYPE_ID = w_stock_check.PRODUIT_TYPE_ID
|
|
|
AND w_stock_check.date_debut = date_trunc('month', now())
|
|
|
WHERE w_stock_check.STOCK_ID IS NULL
|
|
|
GROUP BY 1,2,3,qte_cur,cur.prix_unitaire
|
|
|
;
|
|
|
|
|
|
INSERT INTO w_stock
|
|
|
SELECT
|
|
|
sub.STOCK_ID,
|
|
|
sub.PRODUIT_TYPE_ID,
|
|
|
date_trunc('month', now()) AS date_debut,
|
|
|
COALESCE(SUM(CASE WHEN w_mvt.sens = 'E' THEN QUANTITE ELSE 0 END),0) AS entree_quantite,
|
|
|
COALESCE(SUM(CASE WHEN w_mvt.sens = 'E' THEN QUANTITE ELSE 0 END * w_mvt.PRIX_UNITAIRE),0) AS entree_montant,
|
|
|
COALESCE(SUM(CASE WHEN w_mvt.sens = 'S' THEN QUANTITE ELSE 0 END),0) AS sortie_quantite,
|
|
|
COALESCE(SUM(CASE WHEN w_mvt.sens = 'S' THEN QUANTITE ELSE 0 END * w_mvt.PRIX_UNITAIRE),0) AS sortie_montant,
|
|
|
0 AS prix_unitaire,
|
|
|
COALESCE(SUM(CASE WHEN w_mvt.sens = 'E' THEN -QUANTITE ELSE QUANTITE END),0) AS stock_quantite_debut,
|
|
|
0 AS stock_quantite_fin,
|
|
|
0 AS stock_valeur_fin,
|
|
|
0 AS TVA,
|
|
|
'20991231'::date AS date_fin,
|
|
|
nextval('w_etat_seq'::regclass) AS etat_sequence,
|
|
|
2 AS orig
|
|
|
FROM
|
|
|
(
|
|
|
SELECT stock_id, produit_type_id
|
|
|
FROM w_mvt
|
|
|
GROUP BY 1,2
|
|
|
) sub
|
|
|
LEFT JOIN
|
|
|
(
|
|
|
SELECT stock_id, produit_type_id, (max(array[sub.id::text, prix_unitaire::text]))[2]::numeric AS prix_unitaire, count(distinct sub.id) AS qte_cur
|
|
|
FROM
|
|
|
(
|
|
|
SELECT
|
|
|
produit_type_id,
|
|
|
|
|
|
id,
|
|
|
(max(array[quand::text, stock_id::text]))[2]::numeric AS stock_id,
|
|
|
(max(array[quand::text, produit_type_etat_id::text]))[2]::numeric AS produit_type_etat_id,
|
|
|
(max(array[quand::text, prix_unitaire::text]))[2]::numeric AS prix_unitaire
|
|
|
FROM prod_expert_sante.produit
|
|
|
GROUP BY 1,2
|
|
|
) sub
|
|
|
JOIN prod_expert_sante.STOCK ON STOCK_ID = STOCK.ID
|
|
|
WHERE produit_type_etat_id = 3 AND final != 1
|
|
|
GROUP BY 1,2
|
|
|
) cur ON sub.stock_id = cur.stock_id AND sub.produit_type_id = cur.produit_type_id
|
|
|
LEFT JOIN w_mvt ON w_mvt.STOCK_ID = cur.STOCK_ID
|
|
|
AND w_mvt.PRODUIT_TYPE_ID = cur.PRODUIT_TYPE_ID
|
|
|
AND date_trunc('month',w_mvt.DATE) = date_trunc('month', now())
|
|
|
LEFT JOIN w_stock w_stock_check ON cur.STOCK_ID = w_stock_check.STOCK_ID
|
|
|
AND cur.PRODUIT_TYPE_ID = w_stock_check.PRODUIT_TYPE_ID
|
|
|
WHERE cur.stock_id IS NULL
|
|
|
AND w_stock_check.STOCK_ID IS NULL
|
|
|
GROUP BY 1,2,3,qte_cur,cur.prix_unitaire
|
|
|
;
|
|
|
|
|
|
|
|
|
UPDATE w_stock SET DATE_FIN = DATE_FIN_next
|
|
|
FROM (
|
|
|
SELECT etat_sequence, LEAD(DATE_DEBUT) OVER(PARTITION BY STOCK_ID, PRODUIT_TYPE_ID ORDER BY DATE_DEBUT) - interval '1 day' AS DATE_FIN_next
|
|
|
FROM w_stock
|
|
|
) sub
|
|
|
WHERE sub.etat_sequence = w_stock.etat_sequence AND
|
|
|
DATE_FIN_next IS NOT NULL
|
|
|
;
|
|
|
|
|
|
-- cumul ES
|
|
|
DROP TABLE IF EXISTS w_cumul;
|
|
|
CREATE TEMP TABLE w_cumul AS
|
|
|
SELECT
|
|
|
STOCK_ID,
|
|
|
PRODUIT_TYPE_ID,
|
|
|
date_trunc('month', DATE) AS DATE_DEBUT,
|
|
|
SUM(CASE WHEN SENS = 'E' THEN QUANTITE ELSE 0 END) AS entree_quantite,
|
|
|
SUM(CASE WHEN SENS = 'E' THEN QUANTITE ELSE 0 END * PRIX_UNITAIRE) AS entree_montant,
|
|
|
SUM(CASE WHEN SENS = 'S' THEN QUANTITE ELSE 0 END) AS sortie_quantite,
|
|
|
SUM(CASE WHEN SENS = 'S' THEN QUANTITE ELSE 0 END * PRIX_UNITAIRE) AS sortie_montant,
|
|
|
(MAX(ARRAY[DATE::text,PRIX_UNITAIRE::text]))[2]::numeric as PRIX_UNITAIRE,
|
|
|
(MAX(ARRAY[DATE::text,TVA::text]))[2]::numeric as TVA
|
|
|
FROM w_mvt
|
|
|
GROUP BY 1,2,3
|
|
|
;
|
|
|
|
|
|
-- ajout des mois sans inventaire
|
|
|
-- croissant
|
|
|
INSERT INTO w_stock
|
|
|
SELECT
|
|
|
w_cumul.STOCK_ID,
|
|
|
w_cumul.PRODUIT_TYPE_ID,
|
|
|
w_cumul.DATE_DEBUT,
|
|
|
w_cumul.entree_quantite,
|
|
|
w_cumul.entree_montant,
|
|
|
w_cumul.sortie_quantite,
|
|
|
w_cumul.sortie_montant,
|
|
|
w_cumul.PRIX_UNITAIRE,
|
|
|
COALESCE(w_stock_ref.stock_quantite_fin,0) + COALESCE(SUM(w_cumul.entree_quantite - w_cumul.sortie_quantite) OVER (PARTITION BY w_cumul.STOCK_ID , w_cumul.PRODUIT_TYPE_ID, w_stock_ref.etat_sequence ORDER BY w_cumul.date_debut
|
|
|
ROWS BETWEEN UNBOUNDED PRECEDING AND 1 PRECEDING),0),
|
|
|
COALESCE(w_stock_ref.stock_quantite_fin,0) + SUM(w_cumul.entree_quantite - w_cumul.sortie_quantite) OVER (PARTITION BY w_cumul.STOCK_ID , w_cumul.PRODUIT_TYPE_ID, w_stock_ref.etat_sequence ORDER BY w_cumul.date_debut),
|
|
|
COALESCE(w_stock_ref.stock_valeur_fin,0) + SUM(w_cumul.entree_montant - w_cumul.sortie_montant) OVER (PARTITION BY w_cumul.STOCK_ID , w_cumul.PRODUIT_TYPE_ID, w_stock_ref.etat_sequence ORDER BY w_cumul.date_debut),
|
|
|
w_cumul.TVA,
|
|
|
'20991231'::date AS date_fin,
|
|
|
nextval('w_etat_seq'::regclass) AS etat_sequence,
|
|
|
3 AS orig
|
|
|
FROM w_cumul
|
|
|
JOIN w_stock w_stock_ref ON
|
|
|
w_cumul.STOCK_ID = w_stock_ref.STOCK_ID
|
|
|
AND w_cumul.PRODUIT_TYPE_ID = w_stock_ref.PRODUIT_TYPE_ID
|
|
|
AND w_cumul.DATE_DEBUT BETWEEN w_stock_ref.DATE_DEBUT AND w_stock_ref.DATE_FIN
|
|
|
AND w_cumul.DATE_DEBUT != w_stock_ref.DATE_DEBUT
|
|
|
ORDER BY 1,2,3
|
|
|
;
|
|
|
|
|
|
-- décroissant
|
|
|
INSERT INTO w_stock
|
|
|
SELECT
|
|
|
w_cumul.STOCK_ID,
|
|
|
w_cumul.PRODUIT_TYPE_ID,
|
|
|
w_cumul.DATE_DEBUT,
|
|
|
w_cumul.entree_quantite,
|
|
|
w_cumul.entree_montant,
|
|
|
w_cumul.sortie_quantite,
|
|
|
w_cumul.sortie_montant,
|
|
|
w_cumul.PRIX_UNITAIRE,
|
|
|
w_stock_ref.stock_quantite_debut - COALESCE(SUM(w_cumul.entree_quantite - w_cumul.sortie_quantite) OVER (PARTITION BY w_cumul.STOCK_ID , w_cumul.PRODUIT_TYPE_ID
|
|
|
ORDER BY w_cumul.date_debut DESC),0),
|
|
|
w_stock_ref.stock_quantite_debut - COALESCE(SUM(w_cumul.entree_quantite - w_cumul.sortie_quantite) OVER (PARTITION BY w_cumul.STOCK_ID , w_cumul.PRODUIT_TYPE_ID
|
|
|
ORDER BY w_cumul.date_debut DESC ROWS BETWEEN UNBOUNDED PRECEDING AND 1 PRECEDING),0),
|
|
|
(w_stock_ref.stock_quantite_debut * w_stock_ref.prix_unitaire) - COALESCE(SUM(w_cumul.entree_montant - w_cumul.sortie_montant) OVER (PARTITION BY w_cumul.STOCK_ID, w_cumul.PRODUIT_TYPE_ID
|
|
|
ORDER BY w_cumul.date_debut DESC ROWS BETWEEN UNBOUNDED PRECEDING AND 1 PRECEDING),0),
|
|
|
w_cumul.TVA,
|
|
|
'20991231'::date AS date_fin,
|
|
|
nextval('w_etat_seq'::regclass) AS etat_sequence,
|
|
|
4 AS orig
|
|
|
FROM (
|
|
|
SELECT * FROM w_stock WHERE (STOCK_ID, PRODUIT_TYPE_ID, etat_sequence) IN (SELECT STOCK_ID, PRODUIT_TYPE_ID, MIN(etat_sequence) AS etat_sequence FROM w_stock GROUP BY 1,2)
|
|
|
) w_stock_ref
|
|
|
JOIN w_cumul
|
|
|
ON w_cumul.STOCK_ID = w_stock_ref.STOCK_ID
|
|
|
AND w_cumul.PRODUIT_TYPE_ID = w_stock_ref.PRODUIT_TYPE_ID
|
|
|
AND w_cumul.DATE_DEBUT < w_stock_ref.DATE_DEBUT
|
|
|
ORDER BY 1,2,3
|
|
|
;
|
|
|
|
|
|
UPDATE w_stock
|
|
|
SET prix_unitaire = w_PRODUIT_TYPE_HISTO.PRIX_UNITAIRE,
|
|
|
stock_valeur_fin = w_PRODUIT_TYPE_HISTO.PRIX_UNITAIRE * stock_quantite_fin
|
|
|
FROM w_PRODUIT_TYPE_HISTO
|
|
|
WHERE w_PRODUIT_TYPE_HISTO.PRODUIT_TYPE_ID = w_stock.PRODUIT_TYPE_ID
|
|
|
AND DATE_DEBUT + interval '1 month' - interval '1 day' BETWEEN DATE_EFFET AND w_PRODUIT_TYPE_HISTO.DATE_FIN
|
|
|
;
|
|
|
|
|
|
|
|
|
UPDATE w_stock
|
|
|
SET tva = w_PRODUIT_TYPE_HISTO.TVA
|
|
|
FROM w_PRODUIT_TYPE_HISTO
|
|
|
WHERE w_PRODUIT_TYPE_HISTO.PRODUIT_TYPE_ID = w_stock.PRODUIT_TYPE_ID
|
|
|
AND DATE_DEBUT + interval '1 month' - interval '1 day' BETWEEN DATE_EFFET AND w_PRODUIT_TYPE_HISTO.DATE_FIN
|
|
|
AND w_stock.TVA = 0
|
|
|
;
|
|
|
|
|
|
TRUNCATE eco.p_stock;
|
|
|
|
|
|
INSERT INTO eco.p_stock(
|
|
|
article_id,
|
|
|
date_fin,
|
|
|
date_debut,
|
|
|
ucd_id,
|
|
|
lpp_id,
|
|
|
compte_id,
|
|
|
site_id,
|
|
|
lieu_id,
|
|
|
provider_id,
|
|
|
fournisseur_id,
|
|
|
stock_quantite_debut,
|
|
|
stock_valeur_debut,
|
|
|
stock_valeur_debut_ttc,
|
|
|
entree_quantite,
|
|
|
entree_montant,
|
|
|
pump,
|
|
|
sortie_quantite,
|
|
|
sortie_montant,
|
|
|
stock_quantite_fin,
|
|
|
stock_valeur_fin,
|
|
|
stock_valeur_fin_ttc)
|
|
|
|
|
|
SELECT
|
|
|
coalesce(t_articles.oid,0),
|
|
|
DATE_DEBUT + interval '1 month' - interval '1 day' AS date_fin,
|
|
|
DATE_DEBUT,
|
|
|
ucd_id,
|
|
|
lpp_id,
|
|
|
COALESCE(t_articles.compte_id,0),
|
|
|
COALESCE(t_sites.oid,0),
|
|
|
COALESCE(t_lieux.oid,0),
|
|
|
0::bigint AS provider_id,
|
|
|
t_articles.fournisseur_principal_id AS fournisseur_id,
|
|
|
stock_quantite_debut,
|
|
|
stock_quantite_debut * prix_unitaire AS stock_valeur_debut,
|
|
|
stock_quantite_debut * prix_unitaire * (100 + TVA)/100 AS stock_valeur_debut_ttc,
|
|
|
entree_quantite,
|
|
|
entree_montant,
|
|
|
PRIX_UNITAIRE,
|
|
|
sortie_quantite,
|
|
|
sortie_montant,
|
|
|
stock_quantite_fin,
|
|
|
stock_valeur_fin,
|
|
|
stock_valeur_fin * (100 + TVA)/100
|
|
|
FROM w_stock
|
|
|
LEFT JOIN eco.t_articles ON PRODUIT_TYPE_ID = t_articles.code_original
|
|
|
LEFT JOIN eco.t_lieux ON STOCK_ID = t_lieux.code_original
|
|
|
LEFT JOIN prod_expert_sante.STOCK_SERVICE ON STOCK_SERVICE.STOCK_ID = w_stock.STOCK_ID
|
|
|
LEFT JOIN eco.t_unites_fonctionnelles ON t_unites_fonctionnelles.code_original = SERVICE_ID
|
|
|
LEFT JOIN prod_expert_sante.SERVICE ON SERVICE.ID = SERVICE_ID
|
|
|
LEFT JOIN eco.t_sites ON ETAGE_ID = t_sites.code_original
|
|
|
JOIN prod_expert_sante.STOCK ON w_stock.STOCK_ID = STOCK.ID
|
|
|
WHERE DATE_DEBUT >= '[ENV_ECO_ANNEEDEBUT]0101'
|
|
|
/* suppression des stocks finaux */
|
|
|
AND FINAL != '1'
|
|
|
;
|
|
|
|
|
|
|
|
|
|
|
|
SELECT base.cti_execute('
|
|
|
INSERT INTO eco.p_stock
|
|
|
(
|
|
|
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_debut_ttc,
|
|
|
stock_valeur_fin,
|
|
|
stock_valeur_fin_ttc
|
|
|
)
|
|
|
SELECT
|
|
|
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_ttc,
|
|
|
p_stock.stock_valeur_fin,
|
|
|
p_stock.stock_valeur_fin_ttc
|
|
|
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 >= ''[ENV_ECO_ANNEEDEBUT]0101'' AND
|
|
|
p_stock.stock_quantite_fin != 0 AND
|
|
|
p_stock_next.article_id IS NULL
|
|
|
;',100);
|
|
|
|
|
|
|
|
|
|
|
|
SELECT base.cti_execute('
|
|
|
INSERT INTO eco.p_stock
|
|
|
(
|
|
|
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_debut_ttc,
|
|
|
stock_valeur_fin,
|
|
|
stock_valeur_fin_ttc
|
|
|
)
|
|
|
SELECT
|
|
|
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_ttc,
|
|
|
p_stock.stock_valeur_debut,
|
|
|
p_stock.stock_valeur_debut_ttc
|
|
|
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
|
|
|
p_stock_prev.date_fin + interval ''1 day'' = p_stock.date_debut
|
|
|
WHERE
|
|
|
p_stock.date_debut <= now() AND
|
|
|
p_stock.date_fin >= ''[ENV_ECO_ANNEEDEBUT]0101'' AND
|
|
|
p_stock.stock_quantite_debut != 0 AND
|
|
|
p_stock_prev.article_id IS NULL
|
|
|
;',100);
|
|
|
|
|
|
|
|
|
|
|
|
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');
|
|
|
|
|
|
SELECT eco.cti_update_mvt_qte_stock();
|
|
|
SELECT eco.cti_update_mvt_mnt_stock();
|
|
|
|
|
|
]]></sqlcmd>
|
|
|
</NODE>
|
|
|
|
|
|
<NODE label="Factures">
|
|
|
<sqlcmd><![CDATA[
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
]]></sqlcmd>
|
|
|
</NODE>
|
|
|
|
|
|
</NODE>
|
|
|
<NODE name="POST" label="POST-TRAITEMENTS">
|
|
|
<sqlcmd><![CDATA[
|
|
|
SELECT eco.cti_reorganize_sejour();
|
|
|
SELECT eco.cti_reorganize_sejour_ucd_lpp();
|
|
|
]]></sqlcmd>
|
|
|
</NODE>
|
|
|
|
|
|
</ROOT>
|