|
|
<?xml version="1.0" encoding="ISO-8859-1"?>
|
|
|
<ROOT>
|
|
|
<NODE name="INIT" label="INITIALISATIONS">
|
|
|
|
|
|
<NODE label="Tables diverses">
|
|
|
|
|
|
<sqlcmd><![CDATA[
|
|
|
|
|
|
INSERT INTO eco.t_types_mouvements(code, texte, texte_court, code_original)
|
|
|
SELECT MOVEMENTCODE,MOVEMENTDESCRIPTION,MOVEMENTDESCRIPTION,MOVEMENTID
|
|
|
FROM prod_optim.STOCKMOVEMENT
|
|
|
WHERE 1=1
|
|
|
AND MOVEMENTID NOT IN (SELECT code_original FROM eco.t_types_mouvements)
|
|
|
GROUP BY 1,2,3,4
|
|
|
;
|
|
|
|
|
|
-- Familles
|
|
|
|
|
|
|
|
|
-- fournisseurs
|
|
|
|
|
|
INSERT INTO base.t_codes_postaux(code, texte, texte_court, departement_id)
|
|
|
SELECT POSTALCODE, MAX(CITY), MAX(CITY), MAX(t_departements.oid)
|
|
|
FROM prod_optim.SUPPLIER
|
|
|
LEFT JOIN base.t_codes_postaux ON POSTALCODE = t_codes_postaux.code
|
|
|
JOIN base.t_departements ON
|
|
|
POSTALCODE NOT LIKE '97%' AND substr(POSTALCODE,1,2) = t_departements.code OR
|
|
|
POSTALCODE LIKE '97%' AND substr(POSTALCODE,1,3) = t_departements.code
|
|
|
WHERE t_codes_postaux.oid IS NULL AND
|
|
|
length(POSTALCODE) = 5
|
|
|
GROUP BY 1
|
|
|
;
|
|
|
|
|
|
|
|
|
INSERT INTO eco.t_fournisseurs(code, texte, texte_court, code_original)
|
|
|
SELECT
|
|
|
CASE WHEN t_divers.valeur = '1' THEN SUPPLIERID ELSE SUPPLIERCODE END,
|
|
|
SUPPLIERNAME,
|
|
|
SUPPLIERNAME,
|
|
|
SUPPLIERID
|
|
|
FROM prod_optim.SUPPLIER
|
|
|
LEFT JOIN eco.t_divers ON t_divers.code = 'OP_CODE'
|
|
|
LEFT JOIN eco.t_fournisseurs ON (code_original = SUPPLIERID)
|
|
|
WHERE code_original IS NULL
|
|
|
;
|
|
|
|
|
|
|
|
|
UPDATE eco.t_fournisseurs SET
|
|
|
code = CASE WHEN t_divers.valeur = '1' THEN SUPPLIERID ELSE SUPPLIERCODE END,
|
|
|
texte = SUPPLIER.SUPPLIERNAME,
|
|
|
texte_court = SUPPLIER.SUPPLIERNAME,
|
|
|
adresse = ADDRESS1 || ' ' || SUPPLIER.ADDRESS2,
|
|
|
code_postal_id = COALESCE(t_codes_postaux.oid,0),
|
|
|
ville = SUPPLIER.CITY,
|
|
|
telephone = SUPPLIER.PHONENUMBER,
|
|
|
fax = SUPPLIER.FAXNUMBER,
|
|
|
email = SUPPLIER.EMAIL,
|
|
|
siret = SUPPLIER.SIRENCODE
|
|
|
FROM prod_optim.SUPPLIER
|
|
|
LEFT JOIN eco.t_divers ON t_divers.code = 'OP_CODE'
|
|
|
LEFT JOIN base.t_codes_postaux ON POSTALCODE = t_codes_postaux.code
|
|
|
WHERE code_original = SUPPLIERID AND
|
|
|
(
|
|
|
t_fournisseurs.code IS DISTINCT FROM CASE WHEN t_divers.valeur = '1' THEN SUPPLIERID ELSE SUPPLIERCODE END OR
|
|
|
t_fournisseurs.texte IS DISTINCT FROM SUPPLIER.SUPPLIERNAME OR
|
|
|
t_fournisseurs.texte_court IS DISTINCT FROM SUPPLIER.SUPPLIERNAME OR
|
|
|
t_fournisseurs.adresse IS DISTINCT FROM ADDRESS1 || ' ' || SUPPLIER.ADDRESS2 OR
|
|
|
t_fournisseurs.code_postal_id IS DISTINCT FROM COALESCE(t_codes_postaux.oid,0) OR
|
|
|
t_fournisseurs.ville IS DISTINCT FROM SUPPLIER.CITY OR
|
|
|
t_fournisseurs.telephone IS DISTINCT FROM SUPPLIER.PHONENUMBER OR
|
|
|
t_fournisseurs.fax IS DISTINCT FROM SUPPLIER.FAXNUMBER OR
|
|
|
t_fournisseurs.email IS DISTINCT FROM SUPPLIER.EMAIL OR
|
|
|
t_fournisseurs.siret IS DISTINCT FROM SUPPLIER.SIRENCODE
|
|
|
)
|
|
|
;
|
|
|
|
|
|
-- Types fournisseurs
|
|
|
INSERT INTO eco.t_types_fournisseurs(code_original, code, texte, texte_court)
|
|
|
SELECT SUPPLIERTYPEID, MAX(SUPPLIERTYPECODE), MAX(SUPPLIERTYPENAME), MAX(SUPPLIERTYPENAME)
|
|
|
FROM prod_optim.SUPPLIERTYPE
|
|
|
WHERE SUPPLIERTYPEID NOT IN (SELECT code_original FROM eco.t_types_fournisseurs WHERE code_original IS NOT NULL)
|
|
|
GROUP BY 1
|
|
|
ORDER BY 1
|
|
|
;
|
|
|
|
|
|
UPDATE eco.t_fournisseurs
|
|
|
SET type_id = t_types_fournisseurs.oid
|
|
|
FROM prod_optim.SUPPLIER
|
|
|
JOIN eco.t_types_fournisseurs ON SUPPLIERTYPEID = t_types_fournisseurs.code_original
|
|
|
WHERE SUPPLIERID = t_fournisseurs.code_original AND
|
|
|
type_id IS DISTINCT FROM t_types_fournisseurs.oid
|
|
|
;
|
|
|
|
|
|
-- Unités fonctionnelles
|
|
|
|
|
|
--INSERT INTO eco.t_unites_fonctionnelles(code, texte, texte_court, code_original)
|
|
|
--SELECT CDSEC, LBSEC, LBSEC, CDSEC
|
|
|
--FROM prod_optim.SEC83
|
|
|
-- LEFT JOIN eco.t_unites_fonctionnelles ON (code_original = CDSEC)
|
|
|
--WHERE code_original IS NULL;
|
|
|
--
|
|
|
--UPDATE eco.t_unites_fonctionnelles
|
|
|
--SET texte = LBSEC,
|
|
|
-- texte_court = LBSEC
|
|
|
--FROM prod_optim.SEC83
|
|
|
--WHERE code_original = CDSEC
|
|
|
--AND (texte IS DISTINCT FROM LBSEC);
|
|
|
|
|
|
-- Sites
|
|
|
INSERT INTO eco.t_sites(code, texte, texte_court, code_original)
|
|
|
SELECT
|
|
|
SITECODE,
|
|
|
SITENAME,
|
|
|
SITEPRINTEDNAME,
|
|
|
SITEID
|
|
|
FROM prod_optim.SITE
|
|
|
LEFT JOIN eco.t_sites ON (code_original = SITEID)
|
|
|
WHERE code_original IS NULL;
|
|
|
|
|
|
UPDATE eco.t_sites
|
|
|
SET texte = SITENAME,
|
|
|
texte_court = SITEPRINTEDNAME
|
|
|
FROM prod_optim.SITE
|
|
|
WHERE code_original = SITEID
|
|
|
AND (texte IS DISTINCT FROM SITENAME OR
|
|
|
texte_court IS DISTINCT FROM SITEPRINTEDNAME);
|
|
|
|
|
|
-- Lieux
|
|
|
|
|
|
DROP TABLE IF EXISTS w_location;
|
|
|
CREATE TEMP TABLE w_location AS
|
|
|
SELECT
|
|
|
COALESCE(parent.LOCATIONID,child.LOCATIONID) as plocationid,
|
|
|
COALESCE(parent.SITEID,child.SITEID) as psiteid,
|
|
|
COALESCE(parent.LOCATIONCODE,child.LOCATIONCODE) as plocationcode,
|
|
|
COALESCE(parent.LOCATIONNAME,child.LOCATIONNAME) as plocationname,
|
|
|
COALESCE(parent.parentLocationID,''),
|
|
|
array_agg(child.LOCATIONID) as locationIds
|
|
|
FROM prod_optim.LOCATION child
|
|
|
LEFT JOIN prod_optim.LOCATION parent ON child.PARENTLOCATIONID = parent.LOCATIONID
|
|
|
AND parent.LOCATIONID != parent.SITEID
|
|
|
WHERE child.LOCATIONID IN (SELECT DISTINCT LOCATIONID FROM prod_optim.CATALOGMOVEMENT)
|
|
|
GROUP BY 1,2,3,4,5
|
|
|
ORDER BY 1;
|
|
|
|
|
|
INSERT INTO eco.t_lieux(code, texte, texte_court, code_original)
|
|
|
SELECT
|
|
|
plocationcode,
|
|
|
plocationname,
|
|
|
plocationname,
|
|
|
plocationid
|
|
|
FROM w_location
|
|
|
LEFT JOIN eco.t_lieux ON (code_original = plocationid)
|
|
|
WHERE code_original IS NULL;
|
|
|
|
|
|
UPDATE eco.t_lieux
|
|
|
SET texte = plocationname,
|
|
|
texte_court = plocationname
|
|
|
FROM w_location
|
|
|
WHERE code_original = psiteid
|
|
|
AND (texte IS DISTINCT FROM plocationname);
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
]]></sqlcmd>
|
|
|
</NODE>
|
|
|
|
|
|
|
|
|
|
|
|
<NODE label="Articles">
|
|
|
<sqlcmd><![CDATA[
|
|
|
|
|
|
-- Types
|
|
|
INSERT INTO eco.t_types_articles(code, texte, texte_court, code_original)
|
|
|
SELECT
|
|
|
COALESCE(NULLIF(EQUIPMENTCATEGORYCODE,''),EQUIPMENTCATEGORYNAME),
|
|
|
EQUIPMENTCATEGORYNAME,
|
|
|
LEFT(EQUIPMENTCATEGORYNAME,50),
|
|
|
EQUIPMENTCATEGORYID
|
|
|
FROM prod_optim.EQUIPMENTCATEGORY
|
|
|
LEFT JOIN eco.t_types_articles ON (code_original = EQUIPMENTCATEGORYID)
|
|
|
WHERE 1=1
|
|
|
AND code_original IS NULL
|
|
|
;
|
|
|
|
|
|
UPDATE eco.t_types_articles
|
|
|
SET texte = EQUIPMENTCATEGORYNAME,
|
|
|
texte_court = substr(EQUIPMENTCATEGORYNAME,50)
|
|
|
FROM prod_optim.EQUIPMENTCATEGORY
|
|
|
WHERE
|
|
|
code_original = EQUIPMENTCATEGORYID AND
|
|
|
(texte IS DISTINCT FROM EQUIPMENTCATEGORYNAME);
|
|
|
|
|
|
-- Catégories
|
|
|
|
|
|
INSERT INTO eco.t_categories_articles(code, texte, texte_court, code_original)
|
|
|
SELECT
|
|
|
COALESCE(NULLIF(PRODUCTCATEGORYCODE,''),PRODUCTCATEGORYNAME),
|
|
|
PRODUCTCATEGORYNAME,
|
|
|
LEFT(PRODUCTCATEGORYNAME,50),
|
|
|
PRODUCTCATEGORYID
|
|
|
FROM prod_optim.PRODUCTCATEGORY
|
|
|
LEFT JOIN eco.t_categories_articles ON (code_original = PRODUCTCATEGORYID)
|
|
|
WHERE code_original IS NULL
|
|
|
;
|
|
|
|
|
|
UPDATE eco.t_categories_articles
|
|
|
SET texte = PRODUCTCATEGORYNAME,
|
|
|
texte_court = substr(PRODUCTCATEGORYNAME,50)
|
|
|
FROM prod_optim.PRODUCTCATEGORY
|
|
|
WHERE
|
|
|
code_original = PRODUCTCATEGORYID AND
|
|
|
(texte IS DISTINCT FROM PRODUCTCATEGORYNAME);
|
|
|
|
|
|
INSERT INTO eco.t_sous_categories_articles(code, texte, texte_court, code_original)
|
|
|
SELECT
|
|
|
COALESCE(NULLIF(PRODUCTCATEGORYCODE,''),PRODUCTCATEGORYNAME),
|
|
|
PRODUCTCATEGORYNAME,
|
|
|
LEFT(PRODUCTCATEGORYNAME,50),
|
|
|
PRODUCTCATEGORYID
|
|
|
FROM prod_optim.PRODUCTCATEGORY
|
|
|
LEFT JOIN eco.t_sous_categories_articles ON (code_original = PRODUCTCATEGORYID)
|
|
|
WHERE code_original IS NULL
|
|
|
;
|
|
|
|
|
|
UPDATE eco.t_sous_categories_articles
|
|
|
SET texte = PRODUCTCATEGORYNAME,
|
|
|
texte_court = substr(PRODUCTCATEGORYNAME,50)
|
|
|
FROM prod_optim.PRODUCTCATEGORY
|
|
|
WHERE
|
|
|
code_original = PRODUCTCATEGORYID AND
|
|
|
(texte IS DISTINCT FROM PRODUCTCATEGORYNAME);
|
|
|
|
|
|
|
|
|
-- Gestionnaires
|
|
|
-- Achats
|
|
|
INSERT INTO eco.t_gestionnaires(code_original, code, texte, texte_court)
|
|
|
SELECT
|
|
|
PERSONNELID,
|
|
|
PERSONNELCODE,
|
|
|
LASTNAME || ' ' || FIRSTNAME,
|
|
|
LEFT(LASTNAME || ' ' || FIRSTNAME,50)
|
|
|
FROM
|
|
|
prod_optim.PERSONNEL
|
|
|
WHERE PERSONNELID NOT IN (SELECT code_original FROM eco.t_gestionnaires)
|
|
|
GROUP BY 1,2,3,4
|
|
|
;
|
|
|
|
|
|
-- Unites
|
|
|
INSERT INTO eco.t_unites(code_original, code, texte, texte_court)
|
|
|
SELECT
|
|
|
PRODUCTPACKAGINGID AS code_original,
|
|
|
translate(MAX(PRODUCTPACKAGINGDESCRIPTION),' ','') AS code,
|
|
|
MAX(PRODUCTPACKAGINGDESCRIPTION) AS LBFRM,
|
|
|
substr(MAX(PRODUCTPACKAGINGDESCRIPTION),1,50) AS LBFRM
|
|
|
FROM prod_optim.PRODUCTPACKAGING
|
|
|
WHERE PRODUCTPACKAGINGID NOT IN (SELECT code_original FROM eco.t_unites WHERE code_original IS NOT NULL)
|
|
|
GROUP BY 1
|
|
|
;
|
|
|
|
|
|
|
|
|
-- comptes
|
|
|
INSERT INTO eco.t_compte(code, texte, texte_court, code_original)
|
|
|
SELECT ACCOUNTCODE, ACCOUNTCODE, ACCOUNTCODE, ACCOUNTCODE
|
|
|
FROM prod_optim.PRODUCTCATEGORY
|
|
|
WHERE ACCOUNTCODE <> ''
|
|
|
AND ACCOUNTCODE NOT IN (SELECT code_original FROM eco.t_compte)
|
|
|
GROUP BY 1,2,3,4
|
|
|
;
|
|
|
|
|
|
-- ATC / Cladimed
|
|
|
|
|
|
--INSERT INTO eco.t_classification_atc(code_original, code, texte, texte_court, est_cladimed )
|
|
|
--SELECT CDTHDM, CDTHDM, LBTHDM, LBTHDM, 1
|
|
|
--FROM prod_optim.THP90
|
|
|
-- JOIN (
|
|
|
-- SELECT
|
|
|
-- MERE AS ROOT_CODE,
|
|
|
-- 1 AS cladimed
|
|
|
-- FROM prod_optim.THP90
|
|
|
-- ) sub ON MERE = ROOT_CODE
|
|
|
--LEFT JOIN eco.t_classification_atc ON (code_original = CDTHDM)
|
|
|
--WHERE MERE IS NOT NULL AND
|
|
|
-- code_original IS NULL
|
|
|
-- GROUP BY 1,2,3,4
|
|
|
--;
|
|
|
--
|
|
|
--UPDATE eco.t_classification_atc
|
|
|
--SET texte = LBTHDM,
|
|
|
-- texte_court = LBTHDM,
|
|
|
-- est_cladimed = cladimed
|
|
|
--FROM prod_optim.THP90
|
|
|
-- JOIN (
|
|
|
-- SELECT
|
|
|
-- MERE AS ROOT_CODE,
|
|
|
-- 1 AS cladimed
|
|
|
-- FROM prod_optim.THP90
|
|
|
-- ) sub ON MERE = ROOT_CODE
|
|
|
--WHERE
|
|
|
-- code_original = CDTHDM AND
|
|
|
-- (texte IS DISTINCT FROM LBTHDM);
|
|
|
--
|
|
|
--
|
|
|
-- -- Standard ATC
|
|
|
--SELECT eco.cti_reorganize_classification_atc();
|
|
|
--
|
|
|
-- articles
|
|
|
INSERT INTO eco.t_articles(code, texte, texte_court, code_original)
|
|
|
SELECT
|
|
|
CASE WHEN t_divers.valeur = '1' THEN CATALOGID ELSE CATALOGCODE END,
|
|
|
CATALOGNAME,
|
|
|
SUBSTR(CATALOGNAME,1,50),
|
|
|
CATALOGID
|
|
|
FROM prod_optim.CATALOG
|
|
|
LEFT JOIN eco.t_articles ON (CATALOGID = code_original)
|
|
|
LEFT JOIN eco.t_divers ON t_divers.code = 'OP_CODE'
|
|
|
WHERE code_original IS NULL;
|
|
|
|
|
|
|
|
|
UPDATE eco.t_articles
|
|
|
SET
|
|
|
code = CASE WHEN t_divers.valeur = '1' THEN CATALOGID ELSE CATALOGCODE END,
|
|
|
texte = CATALOGNAME,
|
|
|
texte_court = substr(CATALOGNAME,1,50),
|
|
|
taux_tva_en_cours = base.cti_to_number(LISTPRICEVAT)
|
|
|
FROM prod_optim.CATALOG
|
|
|
LEFT JOIN eco.t_divers ON t_divers.code = 'OP_CODE'
|
|
|
WHERE code_original = CATALOGID
|
|
|
AND (
|
|
|
t_articles.code IS DISTINCT FROM CASE WHEN t_divers.valeur = '1' THEN CATALOGID ELSE CATALOGCODE END OR
|
|
|
t_articles.texte IS DISTINCT FROM CATALOGNAME OR
|
|
|
t_articles.texte_court IS DISTINCT FROM substr(CATALOGNAME,1,50) OR
|
|
|
t_articles.taux_tva_en_cours IS DISTINCT FROM base.cti_to_number(LISTPRICEVAT)
|
|
|
);
|
|
|
|
|
|
|
|
|
UPDATE eco.t_articles SET
|
|
|
type_id = COALESCE(t_types_articles.oid,0),
|
|
|
famille_id = COALESCE(t_familles_articles.oid,0),
|
|
|
sous_famille_id = COALESCE(t_sous_familles_articles.oid,0),
|
|
|
categorie_id = COALESCE(t_categories_articles.oid,0),
|
|
|
sous_categorie_id = COALESCE(t_sous_categories_articles.oid,0),
|
|
|
classification_atc_id = COALESCE(t_classification_atc.oid,0),
|
|
|
unite_stockage_id = COALESCE(t_unites_stockage.oid,0),
|
|
|
unite_distribution_id = COALESCE(t_unites_distribution.oid,0),
|
|
|
lpp_id = COALESCE(t_lpp.oid,0),
|
|
|
ucd_id = COALESCE(t_ucd.oid,0),
|
|
|
compte_id = COALESCE(t_compte.oid,0),
|
|
|
fournisseur_principal_id = COALESCE(t_fournisseurs.oid,0)
|
|
|
--,gere_en_stock = CASE WHEN NONSTOCKE = 1 THEN 0 ELSE 1 END
|
|
|
FROM prod_optim.CATALOG
|
|
|
LEFT JOIN eco.t_familles_articles ON 0 = t_familles_articles.code_original
|
|
|
LEFT JOIN eco.t_sous_familles_articles ON 0 = upper(t_sous_familles_articles.code_original)
|
|
|
LEFT JOIN eco.t_types_articles ON CATALOG.EQUIPMENTCATEGORYID = t_types_articles.code_original
|
|
|
LEFT JOIN eco.t_classification_atc ON CODECLADIMED = upper(t_classification_atc.code_original)
|
|
|
LEFT JOIN prod_optim.PRODUCTCATEGORY ON CATALOG.PRODUCTCATEGORYID = PRODUCTCATEGORY.PRODUCTCATEGORYID
|
|
|
LEFT JOIN eco.t_categories_articles ON
|
|
|
(
|
|
|
PRODUCTCATEGORY.PARENTPRODUCTCATEGORYID <> '' AND PRODUCTCATEGORY.PARENTPRODUCTCATEGORYID = t_categories_articles.code_original OR
|
|
|
PRODUCTCATEGORY.PARENTPRODUCTCATEGORYID = '' AND PRODUCTCATEGORY.PRODUCTCATEGORYID = t_categories_articles.code_original
|
|
|
)
|
|
|
LEFT JOIN eco.t_sous_categories_articles ON CATALOG.PRODUCTCATEGORYID = t_sous_categories_articles.code_original
|
|
|
LEFT JOIN eco.t_unites t_unites_stockage ON 0 = t_unites_stockage.code_original
|
|
|
LEFT JOIN eco.t_unites t_unites_distribution ON 0 = t_unites_distribution.code_original
|
|
|
LEFT JOIN base.t_lpp ON TIPS = t_lpp.code
|
|
|
LEFT JOIN base.t_ucd ON 0 = t_ucd.code
|
|
|
LEFT JOIN eco.t_fournisseurs ON MANUFID = t_fournisseurs.code_original
|
|
|
LEFT JOIN eco.t_compte ON ACCOUNTCODE = t_compte.code_original
|
|
|
WHERE
|
|
|
t_articles.code_original = CATALOGID AND
|
|
|
(
|
|
|
t_articles.type_id IS DISTINCT FROM COALESCE(t_types_articles.oid,0) OR
|
|
|
t_articles.famille_id IS DISTINCT FROM COALESCE(t_familles_articles.oid,0) OR
|
|
|
t_articles.sous_famille_id IS DISTINCT FROM COALESCE(t_sous_familles_articles.oid,0) OR
|
|
|
t_articles.categorie_id IS DISTINCT FROM COALESCE(t_categories_articles.oid,0) OR
|
|
|
t_articles.sous_categorie_id IS DISTINCT FROM COALESCE(t_sous_categories_articles.oid,0) OR
|
|
|
t_articles.classification_atc_id IS DISTINCT FROM COALESCE(t_classification_atc.oid,0) OR
|
|
|
t_articles.unite_stockage_id IS DISTINCT FROM COALESCE(t_unites_stockage.oid,0) OR
|
|
|
t_articles.unite_distribution_id IS DISTINCT FROM COALESCE(t_unites_distribution.oid,0) OR
|
|
|
lpp_id IS DISTINCT FROM COALESCE(t_lpp.oid,0) OR
|
|
|
ucd_id IS DISTINCT FROM COALESCE(t_ucd.oid,0) OR
|
|
|
compte_id IS DISTINCT FROM COALESCE(t_compte.oid,0) OR
|
|
|
fournisseur_principal_id IS DISTINCT FROM COALESCE(t_fournisseurs.oid,0)
|
|
|
);
|
|
|
|
|
|
|
|
|
|
|
|
-- Articles fournisseurs
|
|
|
DROP TABLE IF EXISTS w_article_fournisseur;
|
|
|
CREATE TEMP TABLE w_article_fournisseur AS
|
|
|
SELECT
|
|
|
CATALOGSUPPLIER.CATALOGID || CATALOGSUPPLIER.SUPPLIERID AS code_original,
|
|
|
MAX(t_articles.oid) AS article_id,
|
|
|
MAX(t_fournisseurs.oid) AS fournisseur_id,
|
|
|
(MAX(ARRAY[CATALOGSUPPLIER.WHENUPDATED::text,CASE WHEN CATALOGSUPPLIER.SUPPLIERREF <> '' THEN CATALOGSUPPLIER.SUPPLIERREF ELSE MANUFREFERENCE END]))[2]::text AS code_reference_fournisseur,
|
|
|
MAX(CATALOGNAME) AS texte_reference_fournisseur,
|
|
|
''::text AS code_cip,
|
|
|
''::text AS code_cahpp,
|
|
|
MAX(COALESCE(t_unites.oid,0)) AS unite_approvisionnement_id,
|
|
|
MAX(COALESCE(PRODUCTPACKAGING.QUANTITY,1)) AS nombre_conditionnement_approvisionnement,
|
|
|
(MAX(ARRAY[CATALOGSUPPLIER.WHENUPDATED::text,CATALOGSUPPLIER.LISTPRICE::text]))[2]::numeric AS prix_unitaire_en_cours,
|
|
|
MAX(ISDEFAULTSUPPLIER) AS est_fournisseur_principal,
|
|
|
MAX(t_fournisseurs.oid) AS fournisseur_distributeur_id,
|
|
|
0::bigint AS ucd_id,
|
|
|
MAX(COALESCE(t_lpp.oid,0)) AS lpp_id,
|
|
|
''::text AS code_ucd13
|
|
|
FROM prod_optim.CATALOGSUPPLIER
|
|
|
JOIN prod_optim.CATALOG ON CATALOGSUPPLIER.CATALOGID = CATALOG.CATALOGID
|
|
|
LEFT JOIN prod_optim.PRODUCTPACKAGING ON CATALOG.UNITPACKAGINGID = PRODUCTPACKAGING.PRODUCTPACKAGINGID AND CATALOG.UNITPACKAGINGID <> ''
|
|
|
JOIN eco.t_fournisseurs ON t_fournisseurs.code_original = CATALOGSUPPLIER.SUPPLIERID
|
|
|
JOIN eco.t_articles ON t_articles.code_original = CATALOGSUPPLIER.CATALOGID
|
|
|
LEFT JOIN eco.t_unites ON t_unites.code_original = PRODUCTPACKAGING.PRODUCTPACKAGINGID
|
|
|
LEFT JOIN base.t_lpp ON TIPS = t_lpp.code
|
|
|
GROUP BY 1
|
|
|
;
|
|
|
|
|
|
INSERT INTO eco.t_article_fournisseur(
|
|
|
code_original,
|
|
|
article_id,
|
|
|
fournisseur_id,
|
|
|
code_reference_fournisseur,
|
|
|
texte_reference_fournisseur,
|
|
|
code_cip,
|
|
|
code_cahpp,
|
|
|
unite_approvisionnement_id,
|
|
|
nombre_conditionnement_approvisionnement,
|
|
|
prix_unitaire_en_cours,
|
|
|
est_fournisseur_principal,
|
|
|
fournisseur_distributeur_id,
|
|
|
ucd_id,
|
|
|
lpp_id,
|
|
|
code_ucd13
|
|
|
)
|
|
|
SELECT
|
|
|
code_original,
|
|
|
article_id,
|
|
|
fournisseur_id,
|
|
|
code_reference_fournisseur,
|
|
|
texte_reference_fournisseur,
|
|
|
code_cip,
|
|
|
code_cahpp,
|
|
|
unite_approvisionnement_id,
|
|
|
nombre_conditionnement_approvisionnement,
|
|
|
prix_unitaire_en_cours,
|
|
|
est_fournisseur_principal,
|
|
|
fournisseur_distributeur_id,
|
|
|
ucd_id,
|
|
|
lpp_id,
|
|
|
code_ucd13
|
|
|
FROM w_article_fournisseur
|
|
|
WHERE code_original NOT IN (SELECT t_article_fournisseur.code_original FROM eco.t_article_fournisseur WHERE t_article_fournisseur.code_original IS NOT NULL)
|
|
|
;
|
|
|
|
|
|
UPDATE eco.t_article_fournisseur SET
|
|
|
article_id = w_article_fournisseur.article_id,
|
|
|
fournisseur_id = w_article_fournisseur.fournisseur_id,
|
|
|
fournisseur_distributeur_id = w_article_fournisseur.fournisseur_distributeur_id,
|
|
|
est_fournisseur_principal = w_article_fournisseur.est_fournisseur_principal,
|
|
|
code_reference_fournisseur = w_article_fournisseur.code_reference_fournisseur,
|
|
|
texte_reference_fournisseur = w_article_fournisseur.texte_reference_fournisseur,
|
|
|
code_cip = w_article_fournisseur.code_cip,
|
|
|
code_cahpp = w_article_fournisseur.code_cahpp,
|
|
|
unite_approvisionnement_id = w_article_fournisseur.unite_approvisionnement_id,
|
|
|
nombre_conditionnement_approvisionnement = w_article_fournisseur.nombre_conditionnement_approvisionnement,
|
|
|
prix_unitaire_en_cours = w_article_fournisseur.prix_unitaire_en_cours,
|
|
|
ucd_id = w_article_fournisseur.ucd_id,
|
|
|
code_ucd13 = w_article_fournisseur.code_ucd13
|
|
|
FROM w_article_fournisseur
|
|
|
WHERE t_article_fournisseur.code_original = w_article_fournisseur.code_original AND
|
|
|
(
|
|
|
t_article_fournisseur.article_id IS DISTINCT FROM w_article_fournisseur.article_id OR
|
|
|
t_article_fournisseur.fournisseur_id IS DISTINCT FROM w_article_fournisseur.fournisseur_id OR
|
|
|
t_article_fournisseur.fournisseur_distributeur_id IS DISTINCT FROM w_article_fournisseur.fournisseur_distributeur_id OR
|
|
|
t_article_fournisseur.est_fournisseur_principal IS DISTINCT FROM w_article_fournisseur.est_fournisseur_principal OR
|
|
|
t_article_fournisseur.code_reference_fournisseur IS DISTINCT FROM w_article_fournisseur.code_reference_fournisseur OR
|
|
|
t_article_fournisseur.texte_reference_fournisseur IS DISTINCT FROM w_article_fournisseur.texte_reference_fournisseur OR
|
|
|
t_article_fournisseur.code_cip IS DISTINCT FROM w_article_fournisseur.code_cip OR
|
|
|
t_article_fournisseur.code_cahpp IS DISTINCT FROM w_article_fournisseur.code_cahpp OR
|
|
|
t_article_fournisseur.unite_approvisionnement_id IS DISTINCT FROM w_article_fournisseur.unite_approvisionnement_id OR
|
|
|
t_article_fournisseur.nombre_conditionnement_approvisionnement IS DISTINCT FROM w_article_fournisseur.nombre_conditionnement_approvisionnement OR
|
|
|
t_article_fournisseur.prix_unitaire_en_cours IS DISTINCT FROM w_article_fournisseur.prix_unitaire_en_cours OR
|
|
|
t_article_fournisseur.ucd_id IS DISTINCT FROM w_article_fournisseur.ucd_id OR
|
|
|
t_article_fournisseur.code_ucd13 IS DISTINCT FROM w_article_fournisseur.code_ucd13
|
|
|
)
|
|
|
;
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
]]></sqlcmd>
|
|
|
</NODE>
|
|
|
|
|
|
|
|
|
</NODE>
|
|
|
<NODE name="PROD" label="RECUPERATION DES DONNEES DE PRODUCTION">
|
|
|
<NODE label="Commandes">
|
|
|
<sqlcmd><![CDATA[
|
|
|
|
|
|
|
|
|
SELECT base.cti_disable_index('eco', 'i_commandes_1');
|
|
|
SELECT base.cti_disable_index('eco', 'i_commandes_2');
|
|
|
SELECT base.cti_disable_index('eco', 'i_commandes_3');
|
|
|
SELECT base.cti_disable_index('eco', 'i_commandes_4');
|
|
|
SELECT base.cti_disable_index('eco', 'i_commandes_5');
|
|
|
SELECT base.cti_disable_index('eco', 'i_commandes_6');
|
|
|
SELECT base.cti_disable_index('eco', 'i_commandes_7');
|
|
|
SELECT base.cti_disable_index('eco', 'i_commandes_8');
|
|
|
|
|
|
|
|
|
TRUNCATE eco.p_commandes;
|
|
|
|
|
|
INSERT INTO eco.p_commandes(
|
|
|
code_original,
|
|
|
numero,
|
|
|
date_commande,
|
|
|
date_engagement,
|
|
|
objet,
|
|
|
reference,
|
|
|
date_livraison_prevue,
|
|
|
etat_reception,
|
|
|
date_reception,
|
|
|
etat_liquidation,
|
|
|
fournisseur_id,
|
|
|
gestionnaire_id,
|
|
|
lieu_commande_id,
|
|
|
lieu_facturation_id,
|
|
|
lieu_livraison_id,
|
|
|
unite_fonctionnelle_id,
|
|
|
site_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
|
|
|
ORDERID AS code_original,
|
|
|
ORDERCODE AS numero,
|
|
|
ORDERDATE AS date_commande,
|
|
|
date(date_trunc('month',ORDERDATE)) AS date_engagement,
|
|
|
'' AS objet,
|
|
|
'' AS reference,
|
|
|
date(COALESCE(FORECASTDELIVERYDATE,ORDERDATE)) AS date_livraison_prevue,
|
|
|
'N' etat_reception,
|
|
|
'2099-12-31' AS date_reception,
|
|
|
CASE WHEN INVOICEDORDER = '1' THEN 'T' ELSE 'N' END AS etat_liquidation,
|
|
|
COALESCE(t_fournisseurs.oid, 0) AS fournisseur_id,
|
|
|
COALESCE(t_gestionnaires.oid,0) AS gestionnaire_id,
|
|
|
0::bigint AS lieu_commande_id,
|
|
|
COALESCE(t_lieux_facturation.oid,0) AS lieu_facturation_id,
|
|
|
COALESCE(t_lieux_facturation.oid,0) AS lieu_livraison_id,
|
|
|
0::bigint AS unite_fonctionnelle_id,
|
|
|
COALESCE(t_sites.oid,0) AS site_id,
|
|
|
TOTALORDERGROSS::numeric::numeric AS montant_commande_ht,
|
|
|
TOTALORDERGROSS::numeric*DISCOUNTRATE::numeric AS montant_commande_remise,
|
|
|
TOTALORDERNET::numeric-TOTALORDERGROSS::numeric::numeric AS montant_commande_tva,
|
|
|
CARRIAGECOST AS montant_commande_port,
|
|
|
TOTALORDERNET::numeric::numeric AS montant_commande_total,
|
|
|
0::numeric AS montant_liquidation_ht,
|
|
|
0::numeric AS montant_liquidation_remise,
|
|
|
0::numeric AS montant_liquidation_tva,
|
|
|
0::numeric AS montant_liquidation_port,
|
|
|
0::numeric AS montant_liquidation_total
|
|
|
FROM prod_optim.BLOCORDERING
|
|
|
LEFT JOIN eco.t_fournisseurs ON SUPPLIERID = t_fournisseurs.code_original
|
|
|
LEFT JOIN eco.t_lieux t_lieux_commande ON t_lieux_commande.code_original = 0
|
|
|
LEFT JOIN eco.t_lieux t_lieux_livraison ON t_lieux_livraison.code_original = 0
|
|
|
LEFT JOIN eco.t_lieux t_lieux_facturation ON t_lieux_facturation.code_original = 0
|
|
|
LEFT JOIN eco.t_gestionnaires ON PERSONNELID = t_gestionnaires.code_original
|
|
|
LEFT JOIN eco.t_sites ON SITEID = t_sites.code_original
|
|
|
WHERE ORDERDATE >= '[ENV_ECO_ANNEEDEBUT]-01-01'
|
|
|
ORDER BY 1;
|
|
|
|
|
|
UPDATE eco.p_commandes
|
|
|
SET
|
|
|
date_reception = DELIVERYDATE
|
|
|
FROM (
|
|
|
SELECT
|
|
|
ORDERID,
|
|
|
MAX(date(DELIVERYDATE)) AS DELIVERYDATE
|
|
|
FROM
|
|
|
prod_optim.BLOCDELIVERY
|
|
|
GROUP BY 1) sub
|
|
|
WHERE ORDERID = code_original
|
|
|
;
|
|
|
|
|
|
ANALYSE eco.p_commandes
|
|
|
;
|
|
|
|
|
|
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,
|
|
|
article_id,
|
|
|
unite_approvisionnement_id,
|
|
|
compte_id,
|
|
|
ucd_id,
|
|
|
lpp_id,
|
|
|
|
|
|
quantite_approvisionnement,
|
|
|
prix_unitaire_approvisionnement,
|
|
|
multiplicateur_stockage,
|
|
|
quantite_stockage,
|
|
|
prix_unitaire_stockage,
|
|
|
|
|
|
montant_commande_ht,
|
|
|
montant_commande_remise,
|
|
|
montant_commande_tva,
|
|
|
montant_commande_port,
|
|
|
montant_commande_ttc,
|
|
|
|
|
|
quantite_livraison_approvisionnement,
|
|
|
quantite_livraison_stockage,
|
|
|
montant_livraison_ht,
|
|
|
montant_livraison_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
|
|
|
p_commandes.code_original || '-' || ORDERLINEID AS code_original,
|
|
|
p_commandes.oid AS commande_id,
|
|
|
rank() OVER (PARTITION BY ORDERID ORDER BY ORDERLINEID) AS ligne_commande,
|
|
|
COALESCE(t_articles.texte) AS texte,
|
|
|
COALESCE(t_articles.oid, 0) AS article_id,
|
|
|
0::bigint AS unite_approvisionnement_id,
|
|
|
compte_id, --possibilite de remonter le compte present dans le reglement
|
|
|
COALESCE(t_ucd.oid, t_articles.ucd_id, 0) AS ucd_id,
|
|
|
COALESCE(t_lpp.oid, t_articles.lpp_id, 0) AS lpp_id,
|
|
|
|
|
|
PACKAGEQUANTITY AS quantite_approvisionnement,
|
|
|
UNITPRICE AS prix_unitaire_approvisionnement,
|
|
|
DELIVERYPACKAGINGQUANTITY AS multiplicateur_stockage,
|
|
|
0 AS quantite_stockage,
|
|
|
UNITPRICE AS prix_unitaire_stockage,
|
|
|
|
|
|
PACKAGEQUANTITY*UNITPRICE AS montant_commande_ht,
|
|
|
0 AS montant_commande_remise,
|
|
|
UNITPRICEVAT::numeric*PACKAGEQUANTITY*UNITPRICE/100 AS montant_commande_tva,
|
|
|
0::numeric AS montant_commande_port,
|
|
|
(1+UNITPRICEVAT::numeric/100)*PACKAGEQUANTITY*UNITPRICE AS montant_commande_ttc,
|
|
|
|
|
|
0 AS quantite_livraison_approvisionnement,
|
|
|
0 AS quantite_livraison_stockage,
|
|
|
0 AS montant_livraison_ht,
|
|
|
0 AS montant_livraison_tva,
|
|
|
0 AS montant_livraison_ttc,
|
|
|
'N' AS etat_livraison,
|
|
|
|
|
|
0 as montant_liquidation_ht,
|
|
|
0 as montant_liquidation_remise,
|
|
|
0 as montant_liquidation_tva,
|
|
|
0::numeric AS montant_liquidation_port,
|
|
|
0 AS montant_liquidation_ttc,
|
|
|
'N' AS etat_liquidation,
|
|
|
|
|
|
base.cti_to_number(UNITPRICEVAT) AS taux_tva
|
|
|
FROM prod_optim.BLOCORDERLINE
|
|
|
JOIN eco.p_commandes ON ORDERID = p_commandes.code_original
|
|
|
LEFT JOIN eco.t_articles ON CATALOGID = t_articles.code_original AND t_articles.oid != 0
|
|
|
LEFT JOIN base.t_ucd ON ucd_id = t_ucd.oid AND t_ucd.oid != 0
|
|
|
LEFT JOIN base.t_lpp ON lpp_id = t_lpp.oid AND t_lpp.oid != 0
|
|
|
;
|
|
|
|
|
|
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');
|
|
|
|
|
|
UPDATE eco.p_lignes_commandes
|
|
|
SET
|
|
|
date_reception = DELIVERYDATE,
|
|
|
quantite_livraison_approvisionnement = PACKAGEQUANTITY,
|
|
|
quantite_livraison_stockage = PACKAGEQUANTITY * DELIVERYPACKAGINGQUANTITY,
|
|
|
montant_livraison_ht = PACKAGEQUANTITY * UNITCOST,
|
|
|
montant_livraison_tva = PACKAGEQUANTITY * UNITCOST * UNITCOSTVAT::numeric/100,
|
|
|
montant_livraison_ttc = PACKAGEQUANTITY * UNITCOST * (1 + UNITCOSTVAT::numeric/100),
|
|
|
etat_livraison = CASE WHEN PACKAGEQUANTITY = quantite_approvisionnement THEN 'T'
|
|
|
ELSE 'P' END
|
|
|
FROM
|
|
|
(SELECT
|
|
|
ORDERID,
|
|
|
ORDERLINEID,
|
|
|
DELIVERYPACKAGINGQUANTITY,
|
|
|
MAX(DELIVERYDATE) AS DELIVERYDATE,
|
|
|
SUM(QUANTITY) AS PACKAGEQUANTITY,
|
|
|
MAX(UNITCOST) AS UNITCOST,
|
|
|
MAX(UNITCOSTVAT::numeric) AS UNITCOSTVAT
|
|
|
FROM prod_optim.BLOCDELIVERY
|
|
|
JOIN prod_optim.BLOCDELIVERYLINE ON BLOCDELIVERY.DELIVERYID = BLOCDELIVERYLINE.DELIVERYID
|
|
|
GROUP BY 1,2,3
|
|
|
) sub
|
|
|
WHERE ORDERID || '-' || ORDERLINEID = 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,
|
|
|
etat_liquidation = 'T'
|
|
|
FROM
|
|
|
eco.p_commandes
|
|
|
WHERE 1=1 AND
|
|
|
p_commandes.oid = commande_id AND
|
|
|
p_commandes.etat_liquidation = 'T'
|
|
|
;
|
|
|
|
|
|
DROP TABLE IF EXISTS W_COM_TOT;
|
|
|
CREATE TEMP TABLE w_COM_TOT AS
|
|
|
SELECT
|
|
|
commande_id,
|
|
|
SUM(p_lignes_commandes.montant_commande_ht) AS montant_commande_ht,
|
|
|
SUM(p_lignes_commandes.montant_commande_tva) AS montant_commande_tva,
|
|
|
SUM(p_lignes_commandes.montant_commande_ttc) AS montant_commande_total,
|
|
|
SUM(p_lignes_commandes.montant_liquidation_ht) AS montant_liquidation_ht,
|
|
|
SUM(p_lignes_commandes.montant_liquidation_tva) AS montant_liquidation_tva,
|
|
|
SUM(p_lignes_commandes.montant_liquidation_ttc) AS montant_liquidation_total
|
|
|
FROM eco.p_lignes_commandes
|
|
|
GROUP BY 1
|
|
|
;
|
|
|
|
|
|
VACUUM ANALYSE w_COM_TOT;
|
|
|
|
|
|
CREATE INDEX commande_id_i ON w_COM_TOT using btree(commande_id);
|
|
|
|
|
|
-- maj des commandes
|
|
|
/*UPDATE eco.p_commandes
|
|
|
SET
|
|
|
montant_commande_ht = w_COM_TOT.montant_commande_ht,
|
|
|
montant_commande_remise = w_COM_TOT.montant_commande_ht,
|
|
|
montant_commande_tva = w_COM_TOT.montant_commande_tva,
|
|
|
montant_commande_total = w_COM_TOT.montant_commande_total,
|
|
|
montant_liquidation_ht = w_COM_TOT.montant_liquidation_ht,
|
|
|
montant_liquidation_remise = w_COM_TOT.montant_liquidation_remise,
|
|
|
montant_liquidation_tva = w_COM_TOT.montant_liquidation_tva,
|
|
|
montant_liquidation_total = w_COM_TOT.montant_liquidation_total
|
|
|
FROM
|
|
|
w_COM_TOT
|
|
|
WHERE commande_id = p_commandes.oid
|
|
|
;*/
|
|
|
]]></sqlcmd>
|
|
|
</NODE>
|
|
|
|
|
|
<NODE label="Mouvements">
|
|
|
<sqlcmd><![CDATA[
|
|
|
|
|
|
-- Préparation table
|
|
|
DROP TABLE IF EXISTS w_CATALOGMOVEMENT;
|
|
|
CREATE TEMP TABLE w_CATALOGMOVEMENT AS
|
|
|
SELECT *,
|
|
|
''::text AS DELIVERYID,
|
|
|
''::text AS DELIVERYCODE,
|
|
|
''::text AS DELIVERYLINEID,
|
|
|
''::text AS ORDERID,
|
|
|
''::text AS ORDERCODE,
|
|
|
''::text AS ORDERLINEID,
|
|
|
0::numeric AS commande_id,
|
|
|
0::numeric AS ligne_commande,
|
|
|
''::text AS no_sejour,
|
|
|
''::text AS no_patient
|
|
|
FROM prod_optim.CATALOGMOVEMENT
|
|
|
;
|
|
|
|
|
|
ANALYSE w_CATALOGMOVEMENT
|
|
|
;
|
|
|
|
|
|
|
|
|
|
|
|
DROP TABLE IF EXISTS w_CATALOGMOVEMENT_ORDER;
|
|
|
CREATE TEMP TABLE w_CATALOGMOVEMENT_ORDER AS
|
|
|
SELECT CATALOGMOVEMENTID,
|
|
|
MAX(BLOCDELIVERYLINE.DELIVERYID) AS DELIVERYID,
|
|
|
MAX(BLOCDELIVERY.DELIVERYCODE) AS DELIVERYCODE,
|
|
|
MAX(BLOCDELIVERYLINE.DELIVERYLINEID) AS DELIVERYLINEID,
|
|
|
MAX(BLOCORDERING.ORDERCODE) AS ORDERCODE,
|
|
|
MAX(BLOCORDERLINE.ORDERID) AS ORDERID,
|
|
|
MAX(BLOCORDERLINE.ORDERLINEID) AS ORDERLINEID
|
|
|
FROM w_CATALOGMOVEMENT
|
|
|
JOIN prod_optim.BLOCDELIVERYLINE ON
|
|
|
w_CATALOGMOVEMENT.CATALOGSTOCKID = BLOCDELIVERYLINE.CATALOGSTOCKID AND
|
|
|
w_CATALOGMOVEMENT.CATALOGID = BLOCDELIVERYLINE.CATALOGID
|
|
|
JOIN prod_optim.BLOCDELIVERY ON
|
|
|
BLOCDELIVERYLINE.DELIVERYID = BLOCDELIVERY.DELIVERYID AND
|
|
|
date(w_CATALOGMOVEMENT.MOVEMENTDATETIME) = date(DELIVERYDATE)
|
|
|
JOIN prod_optim.BLOCORDERLINE ON BLOCDELIVERYLINE.ORDERLINEID = BLOCORDERLINE.ORDERLINEID
|
|
|
JOIN prod_optim.BLOCORDERING ON BLOCORDERLINE.ORDERID = BLOCORDERING.ORDERID
|
|
|
WHERE w_CATALOGMOVEMENT.CATALOGSTOCKID <> '' AND
|
|
|
w_CATALOGMOVEMENT.MOVEMENTQUANTITY > 0
|
|
|
GROUP BY 1
|
|
|
HAVING count(DISTINCT BLOCORDERLINE.ORDERLINEID) = 1
|
|
|
;
|
|
|
|
|
|
ANALYSE w_CATALOGMOVEMENT_ORDER
|
|
|
;
|
|
|
|
|
|
UPDATE w_CATALOGMOVEMENT SET
|
|
|
DELIVERYID = w_CATALOGMOVEMENT_ORDER.DELIVERYID,
|
|
|
DELIVERYCODE = w_CATALOGMOVEMENT_ORDER.DELIVERYCODE,
|
|
|
DELIVERYLINEID = w_CATALOGMOVEMENT_ORDER.DELIVERYLINEID,
|
|
|
ORDERID = w_CATALOGMOVEMENT_ORDER.ORDERID,
|
|
|
ORDERCODE = w_CATALOGMOVEMENT_ORDER.ORDERCODE,
|
|
|
ORDERLINEID = w_CATALOGMOVEMENT_ORDER.ORDERLINEID
|
|
|
FROM w_CATALOGMOVEMENT_ORDER
|
|
|
WHERE w_CATALOGMOVEMENT_ORDER.CATALOGMOVEMENTID = w_CATALOGMOVEMENT.CATALOGMOVEMENTID
|
|
|
;
|
|
|
|
|
|
DROP TABLE IF EXISTS w_CATALOGMOVEMENT_ORDER;
|
|
|
CREATE TEMP TABLE w_CATALOGMOVEMENT_ORDER AS
|
|
|
SELECT CATALOGMOVEMENTID,
|
|
|
MAX(BLOCDELIVERYLINE.DELIVERYID) AS DELIVERYID,
|
|
|
MAX(BLOCDELIVERY.DELIVERYCODE) AS DELIVERYCODE,
|
|
|
MAX(BLOCDELIVERYLINE.DELIVERYLINEID) AS DELIVERYLINEID,
|
|
|
MAX(BLOCORDERING.ORDERCODE) AS ORDERCODE,
|
|
|
MAX(BLOCORDERLINE.ORDERID) AS ORDERID,
|
|
|
MAX(BLOCORDERLINE.ORDERLINEID) AS ORDERLINEID
|
|
|
FROM w_CATALOGMOVEMENT
|
|
|
JOIN prod_optim.BLOCDELIVERYLINE ON
|
|
|
w_CATALOGMOVEMENT.CATALOGSTOCKID = BLOCDELIVERYLINE.CATALOGSTOCKID AND
|
|
|
w_CATALOGMOVEMENT.CATALOGID = BLOCDELIVERYLINE.CATALOGID
|
|
|
JOIN prod_optim.BLOCDELIVERY ON
|
|
|
BLOCDELIVERYLINE.DELIVERYID = BLOCDELIVERY.DELIVERYID AND
|
|
|
date(w_CATALOGMOVEMENT.MOVEMENTDATETIME) = date(DELIVERYDATE)
|
|
|
JOIN prod_optim.BLOCORDERLINE ON BLOCDELIVERYLINE.ORDERLINEID = BLOCORDERLINE.ORDERLINEID
|
|
|
JOIN prod_optim.BLOCORDERING ON BLOCORDERLINE.ORDERID = BLOCORDERING.ORDERID
|
|
|
WHERE w_CATALOGMOVEMENT.ORDERID = '' AND
|
|
|
w_CATALOGMOVEMENT.CATALOGSTOCKID <> '' AND
|
|
|
w_CATALOGMOVEMENT.MOVEMENTQUANTITY > 0 AND
|
|
|
w_CATALOGMOVEMENT.FURTHERINFORMATION LIKE '% ' || BLOCORDERING.ORDERCODE
|
|
|
GROUP BY 1
|
|
|
HAVING count(DISTINCT BLOCORDERLINE.ORDERLINEID) = 1
|
|
|
;
|
|
|
|
|
|
ANALYSE w_CATALOGMOVEMENT_ORDER
|
|
|
;
|
|
|
|
|
|
UPDATE w_CATALOGMOVEMENT SET
|
|
|
DELIVERYID = w_CATALOGMOVEMENT_ORDER.DELIVERYID,
|
|
|
DELIVERYCODE = w_CATALOGMOVEMENT_ORDER.DELIVERYCODE,
|
|
|
DELIVERYLINEID = w_CATALOGMOVEMENT_ORDER.DELIVERYLINEID,
|
|
|
ORDERID = w_CATALOGMOVEMENT_ORDER.ORDERID,
|
|
|
ORDERCODE = w_CATALOGMOVEMENT_ORDER.ORDERCODE,
|
|
|
ORDERLINEID = w_CATALOGMOVEMENT_ORDER.ORDERLINEID
|
|
|
FROM w_CATALOGMOVEMENT_ORDER
|
|
|
WHERE w_CATALOGMOVEMENT_ORDER.CATALOGMOVEMENTID = w_CATALOGMOVEMENT.CATALOGMOVEMENTID
|
|
|
;
|
|
|
|
|
|
DROP TABLE IF EXISTS w_CATALOGMOVEMENT_ORDER;
|
|
|
CREATE TEMP TABLE w_CATALOGMOVEMENT_ORDER AS
|
|
|
SELECT
|
|
|
w_CATALOGMOVEMENT.CATALOGMOVEMENTID,
|
|
|
MAX(BLOCORDERING.ORDERCODE) AS ORDERCODE,
|
|
|
MAX(BLOCORDERLINE.ORDERID) AS ORDERID,
|
|
|
MAX(BLOCORDERLINE.ORDERLINEID) AS ORDERLINEID
|
|
|
FROM w_CATALOGMOVEMENT
|
|
|
JOIN prod_optim.opeproduct ON 1=1
|
|
|
AND opeproduct.catalogstockid = w_CATALOGMOVEMENT.catalogstockid
|
|
|
AND opeproduct.catalogid = w_CATALOGMOVEMENT.catalogid
|
|
|
JOIN prod_optim.BLOCORDERLINE ON BLOCORDERLINE.opeproductid = opeproduct.opeproductid
|
|
|
JOIN prod_optim.BLOCORDERING ON BLOCORDERLINE.ORDERID = BLOCORDERING.ORDERID
|
|
|
GROUP BY 1
|
|
|
HAVING count(DISTINCT BLOCORDERLINE.ORDERLINEID) = 1
|
|
|
;
|
|
|
|
|
|
ANALYSE w_CATALOGMOVEMENT_ORDER
|
|
|
;
|
|
|
|
|
|
UPDATE w_CATALOGMOVEMENT SET
|
|
|
ORDERID = w_CATALOGMOVEMENT_ORDER.ORDERID,
|
|
|
ORDERCODE = w_CATALOGMOVEMENT_ORDER.ORDERCODE,
|
|
|
ORDERLINEID = w_CATALOGMOVEMENT_ORDER.ORDERLINEID
|
|
|
FROM w_CATALOGMOVEMENT_ORDER
|
|
|
WHERE w_CATALOGMOVEMENT_ORDER.CATALOGMOVEMENTID = w_CATALOGMOVEMENT.CATALOGMOVEMENTID
|
|
|
;
|
|
|
|
|
|
|
|
|
WITH sejours as (
|
|
|
SELECT
|
|
|
CATALOGMOVEMENT.CATALOGMOVEMENTID,
|
|
|
max(patientstaycode) as PATIENTSTAYCODE,
|
|
|
max(PATIENT.PERMANENTCODE) as PATIENTCODE
|
|
|
FROM prod_optim.opeproduct
|
|
|
JOIN prod_optim.catalogmovement ON 1=1
|
|
|
AND opeproduct.catalogstockid = CATALOGMOVEMENT.catalogstockid
|
|
|
AND opeproduct.catalogid = CATALOGMOVEMENT.catalogid
|
|
|
JOIN prod_optim.patientstay ON patientstay.patientstayid = opeproduct.patientstayid
|
|
|
JOIN prod_optim.PATIENT ON PATIENTSTAY.PATIENTID = PATIENT.PATIENTID
|
|
|
WHERE opeproduct.catalogstockid <> ''
|
|
|
GROUP BY 1
|
|
|
)
|
|
|
UPDATE w_CATALOGMOVEMENT SET
|
|
|
no_sejour = sejours.PATIENTSTAYCODE,
|
|
|
no_patient = sejours.PATIENTCODE
|
|
|
FROM sejours
|
|
|
WHERE sejours.CATALOGMOVEMENTID = w_CATALOGMOVEMENT.CATALOGMOVEMENTID
|
|
|
;
|
|
|
|
|
|
|
|
|
DROP TABLE IF EXISTS w_CATALOGMOVEMENT_ORDER;
|
|
|
CREATE TEMP TABLE w_CATALOGMOVEMENT_ORDER AS
|
|
|
SELECT CATALOGMOVEMENTID,
|
|
|
MAX(BLOCDELIVERYLINE.DELIVERYID) AS DELIVERYID,
|
|
|
MAX(BLOCDELIVERY.DELIVERYCODE) AS DELIVERYCODE,
|
|
|
MAX(BLOCDELIVERYLINE.DELIVERYLINEID) AS DELIVERYLINEID,
|
|
|
MAX(BLOCORDERING.ORDERCODE) AS ORDERCODE,
|
|
|
MAX(BLOCORDERLINE.ORDERID) AS ORDERID,
|
|
|
MAX(BLOCORDERLINE.ORDERLINEID) AS ORDERLINEID
|
|
|
FROM w_CATALOGMOVEMENT
|
|
|
JOIN prod_optim.BLOCDELIVERYLINE ON
|
|
|
w_CATALOGMOVEMENT.CATALOGID = BLOCDELIVERYLINE.CATALOGID
|
|
|
JOIN prod_optim.BLOCDELIVERY ON
|
|
|
BLOCDELIVERYLINE.DELIVERYID = BLOCDELIVERY.DELIVERYID AND
|
|
|
date(w_CATALOGMOVEMENT.MOVEMENTDATETIME) = date(DELIVERYDATE)
|
|
|
JOIN prod_optim.BLOCORDERLINE ON BLOCDELIVERYLINE.ORDERLINEID = BLOCORDERLINE.ORDERLINEID
|
|
|
JOIN prod_optim.BLOCORDERING ON BLOCORDERLINE.ORDERID = BLOCORDERING.ORDERID
|
|
|
WHERE w_CATALOGMOVEMENT.ORDERID = '' AND
|
|
|
w_CATALOGMOVEMENT.CATALOGSTOCKID <> '' AND
|
|
|
w_CATALOGMOVEMENT.MOVEMENTQUANTITY > 0 AND
|
|
|
w_CATALOGMOVEMENT.FURTHERINFORMATION LIKE '% ' || BLOCORDERING.ORDERCODE
|
|
|
GROUP BY 1
|
|
|
HAVING count(DISTINCT BLOCORDERLINE.ORDERLINEID) = 1
|
|
|
;
|
|
|
|
|
|
ANALYSE w_CATALOGMOVEMENT_ORDER
|
|
|
;
|
|
|
|
|
|
UPDATE w_CATALOGMOVEMENT SET
|
|
|
DELIVERYID = w_CATALOGMOVEMENT_ORDER.DELIVERYID,
|
|
|
DELIVERYCODE = w_CATALOGMOVEMENT_ORDER.DELIVERYCODE,
|
|
|
DELIVERYLINEID = w_CATALOGMOVEMENT_ORDER.DELIVERYLINEID,
|
|
|
ORDERID = w_CATALOGMOVEMENT_ORDER.ORDERID,
|
|
|
ORDERCODE = w_CATALOGMOVEMENT_ORDER.ORDERCODE,
|
|
|
ORDERLINEID = w_CATALOGMOVEMENT_ORDER.ORDERLINEID
|
|
|
FROM w_CATALOGMOVEMENT_ORDER
|
|
|
WHERE w_CATALOGMOVEMENT_ORDER.CATALOGMOVEMENTID = w_CATALOGMOVEMENT.CATALOGMOVEMENTID
|
|
|
;
|
|
|
|
|
|
|
|
|
DROP TABLE IF EXISTS w_CATALOGMOVEMENT_ORDER;
|
|
|
CREATE TEMP TABLE w_CATALOGMOVEMENT_ORDER AS
|
|
|
SELECT MOVEMENTID, CATALOGSTOCKID, CATALOGID, LOCATIONID, SERIALNO, date(MOVEMENTDATETIME) AS MOVEMENTDATETIME,
|
|
|
MAX(ORDERID) AS ORDERID,
|
|
|
MAX(ORDERCODE) AS ORDERCODE,
|
|
|
MAX(ORDERLINEID) AS ORDERLINEID,
|
|
|
MAX(DELIVERYID) AS DELIVERYID,
|
|
|
MAX(DELIVERYCODE) AS DELIVERYCODE,
|
|
|
MAX(DELIVERYLINEID) AS DELIVERYLINEID
|
|
|
FROM w_CATALOGMOVEMENT
|
|
|
GROUP BY 1,2,3,4,5,6
|
|
|
HAVING count(DISTINCT CASE WHEN ORDERLINEID <> '' THEN ORDERLINEID ELSE NULL END) = 1 AND
|
|
|
MAX(ORDERLINEID) <> '' AND
|
|
|
MIN(ORDERLINEID) = ''
|
|
|
;
|
|
|
|
|
|
ANALYSE w_CATALOGMOVEMENT_ORDER
|
|
|
;
|
|
|
|
|
|
UPDATE w_CATALOGMOVEMENT SET
|
|
|
DELIVERYID = w_CATALOGMOVEMENT_ORDER.DELIVERYID,
|
|
|
DELIVERYCODE = w_CATALOGMOVEMENT_ORDER.DELIVERYCODE,
|
|
|
DELIVERYLINEID = w_CATALOGMOVEMENT_ORDER.DELIVERYLINEID,
|
|
|
ORDERID = w_CATALOGMOVEMENT_ORDER.ORDERID,
|
|
|
ORDERCODE = w_CATALOGMOVEMENT_ORDER.ORDERCODE,
|
|
|
ORDERLINEID = w_CATALOGMOVEMENT_ORDER.ORDERLINEID
|
|
|
FROM w_CATALOGMOVEMENT_ORDER
|
|
|
WHERE w_CATALOGMOVEMENT_ORDER.MOVEMENTID = w_CATALOGMOVEMENT.MOVEMENTID AND
|
|
|
w_CATALOGMOVEMENT_ORDER.CATALOGSTOCKID = w_CATALOGMOVEMENT.CATALOGSTOCKID AND
|
|
|
w_CATALOGMOVEMENT_ORDER.CATALOGID = w_CATALOGMOVEMENT.CATALOGID AND
|
|
|
w_CATALOGMOVEMENT_ORDER.LOCATIONID = w_CATALOGMOVEMENT.LOCATIONID AND
|
|
|
w_CATALOGMOVEMENT_ORDER.SERIALNO = w_CATALOGMOVEMENT.SERIALNO AND
|
|
|
date(w_CATALOGMOVEMENT_ORDER.MOVEMENTDATETIME) = date(w_CATALOGMOVEMENT.MOVEMENTDATETIME)
|
|
|
;
|
|
|
|
|
|
|
|
|
UPDATE w_CATALOGMOVEMENT SET
|
|
|
commande_id = p_commandes.oid
|
|
|
FROM eco.p_commandes
|
|
|
WHERE ORDERID <> '' AND
|
|
|
p_commandes.code_original = ORDERID
|
|
|
;
|
|
|
|
|
|
UPDATE w_CATALOGMOVEMENT SET
|
|
|
ligne_commande = p_lignes_commandes.ligne_commande
|
|
|
FROM eco.p_lignes_commandes
|
|
|
WHERE ORDERLINEID <> '' AND
|
|
|
p_lignes_commandes.code_original = ORDERID || '-' || ORDERLINEID
|
|
|
;
|
|
|
|
|
|
CREATE INDEX i_w_CATALOGMOVEMENT_ORDERID ON w_CATALOGMOVEMENT USING BTREE(ORDERID)
|
|
|
;
|
|
|
|
|
|
UPDATE w_CATALOGMOVEMENT SET
|
|
|
no_sejour = PATIENTSTAY.PATIENTSTAYCODE,
|
|
|
no_patient = PATIENT.PERMANENTCODE
|
|
|
FROM prod_optim.ORDERPATIENTSTAY
|
|
|
JOIN prod_optim.PATIENTSTAY ON ORDERPATIENTSTAY.PATIENTSTAYID = PATIENTSTAY.PATIENTSTAYID
|
|
|
JOIN prod_optim.PATIENT ON PATIENTSTAY.PATIENTID = PATIENT.PATIENTID
|
|
|
WHERE w_CATALOGMOVEMENT.ORDERID != '' AND w_CATALOGMOVEMENT.ORDERID = ORDERPATIENTSTAY.ORDERID
|
|
|
;
|
|
|
|
|
|
ANALYSE w_CATALOGMOVEMENT
|
|
|
;
|
|
|
|
|
|
CREATE INDEX i_w_CATALOGMOVEMENT_CATALOGSTOCKID ON w_CATALOGMOVEMENT USING BTREE(CATALOGSTOCKID);
|
|
|
CREATE INDEX i_w_CATALOGMOVEMENT_LOCATIONID ON w_CATALOGMOVEMENT USING BTREE(LOCATIONID);
|
|
|
CREATE INDEX i_w_CATALOGMOVEMENT_CATALOGID ON w_CATALOGMOVEMENT USING BTREE(CATALOGID);
|
|
|
CREATE INDEX i_w_CATALOGMOVEMENT_WHOUPDATED ON w_CATALOGMOVEMENT USING BTREE(WHOUPDATED);
|
|
|
|
|
|
DROP TABLE IF EXISTS temp.w_CATALOGMOVEMENT; CREATE TABLE temp.w_CATALOGMOVEMENT AS SELECT * FROM w_CATALOGMOVEMENT;
|
|
|
|
|
|
|
|
|
-- mouvements
|
|
|
|
|
|
TRUNCATE eco.p_mouvements_articles;
|
|
|
|
|
|
SELECT base.cti_disable_index('eco', 'i_mouvements_articles_1');
|
|
|
SELECT base.cti_disable_index('eco', 'i_mouvements_articles_2');
|
|
|
SELECT base.cti_disable_index('eco', 'i_mouvements_articles_3');
|
|
|
SELECT base.cti_disable_index('eco', 'i_mouvements_articles_4');
|
|
|
SELECT base.cti_disable_index('eco', 'i_mouvements_articles_5');
|
|
|
SELECT base.cti_disable_index('eco', 'i_mouvements_articles_6');
|
|
|
SELECT base.cti_disable_index('eco', 'i_mouvements_articles_7');
|
|
|
SELECT base.cti_disable_index('eco', 'i_mouvements_articles_8');
|
|
|
SELECT base.cti_disable_index('eco', 'i_mouvements_articles_9');
|
|
|
SELECT base.cti_disable_index('eco', 'i_mouvements_articles_10');
|
|
|
|
|
|
|
|
|
DROP TABLE IF EXISTS w_STOCK_FIN;
|
|
|
CREATE TEMP TABLE w_STOCK_FIN AS
|
|
|
SELECT
|
|
|
LOCATIONID,
|
|
|
CATALOGID,
|
|
|
MAX(mvt_id) AS mvt_id,
|
|
|
SUM(res) AS qte_fin
|
|
|
FROM (
|
|
|
SELECT
|
|
|
CATALOGSTOCK.LOCATIONID,
|
|
|
CATALOGSTOCK.CATALOGID,
|
|
|
CATALOGSTOCK.CATALOGSTOCKID,
|
|
|
MAX(CATALOGMOVEMENTID) AS mvt_id,
|
|
|
(MAX(ARRAY[CATALOGMOVEMENTID::text,RESULTSTOCK::text]))[2]::numeric AS res
|
|
|
FROM prod_optim.CATALOGMOVEMENT
|
|
|
JOIN prod_optim.CATALOGSTOCK ON CATALOGSTOCK.CATALOGSTOCKID = CATALOGMOVEMENT.CATALOGSTOCKID
|
|
|
GROUP BY 1,2,3
|
|
|
ORDER BY 5 desc
|
|
|
) sub
|
|
|
GROUP BY 1,2
|
|
|
;
|
|
|
|
|
|
|
|
|
CREATE INDEX w_stock_loc_i ON w_STOCK_FIN using btree(LOCATIONID);
|
|
|
CREATE INDEX w_stock_catalog_i ON w_STOCK_FIN using btree(CATALOGID);
|
|
|
|
|
|
|
|
|
INSERT INTO eco.p_mouvements_articles(
|
|
|
code_original,
|
|
|
date,
|
|
|
sens_mouvement,
|
|
|
type_mouvement_id,
|
|
|
texte,
|
|
|
gestionnaire_id,
|
|
|
lieu_id,
|
|
|
unite_fonctionnelle_id,
|
|
|
article_id,
|
|
|
compte_id,
|
|
|
fournisseur_id,
|
|
|
commande_id,
|
|
|
ligne_commande,
|
|
|
site_id,
|
|
|
lpp_id,
|
|
|
ucd_id,
|
|
|
prix_unitaire,
|
|
|
entree_quantite,
|
|
|
sortie_quantite,
|
|
|
entree_montant_ht,
|
|
|
entree_montant,
|
|
|
sortie_montant_ht,
|
|
|
sortie_montant,
|
|
|
stock_quantite_debut,
|
|
|
stock_quantite_fin,
|
|
|
date_fin,
|
|
|
est_premier_jour,
|
|
|
est_dernier_jour,
|
|
|
no_sejour
|
|
|
)
|
|
|
SELECT
|
|
|
CATALOGMOVEMENTID AS code_original,
|
|
|
MOVEMENTDATETIME AS date,
|
|
|
CASE WHEN MOVEMENTQUANTITY > 0 THEN 'E' ELSE 'S' END AS sens_mouvement,
|
|
|
COALESCE(t_types_mouvements.oid,0) AS type_mouvement_id,
|
|
|
COALESCE(NULLIF(FURTHERINFORMATION,''), t_types_mouvements.code) || ' (' || t_articles.code || ')' AS texte,
|
|
|
COALESCE(t_gestionnaires.oid,0) AS gestionnaire_id,
|
|
|
COALESCE(t_lieux.oid,0) AS lieu_id,
|
|
|
COALESCE(t_unites_fonctionnelles.oid,0) AS unite_fonctionnelle_id,
|
|
|
t_articles.oid,
|
|
|
compte_id,
|
|
|
fournisseur_principal_id AS fournisseur_id,
|
|
|
CATALOGMOVEMENT.commande_id,
|
|
|
0 AS ligne_commande,
|
|
|
COALESCE(t_sites.oid,0) AS site_id,
|
|
|
COALESCE(t_articles.lpp_id,0) AS lppid,
|
|
|
COALESCE(t_articles.ucd_id,0) AS ucd_id,
|
|
|
CASE WHEN UNITPRICE != 0 THEN UNITPRICE ELSE LAG(UNITPRICE) OVER (PARTITION BY CATALOGMOVEMENT.CATALOGID,CASE WHEN UNITPRICE!= 0 THEN 1 ELSE 0 END ORDER BY MOVEMENTDATETIME) END AS prix_unitaire,
|
|
|
CASE WHEN MOVEMENTQUANTITY > 0 THEN MOVEMENTQUANTITY ELSE 0 END AS entree_quantite,
|
|
|
CASE WHEN MOVEMENTQUANTITY < 0 THEN -MOVEMENTQUANTITY ELSE 0 END AS sortie_quantite,
|
|
|
0 AS entree_montant_ht,
|
|
|
0 AS entree_montant,
|
|
|
0 AS sortie_montant_ht,
|
|
|
0 AS sortie_montant,
|
|
|
qte_fin-SUM(MOVEMENTQUANTITY) OVER (PARTITION BY CATALOGMOVEMENT.CATALOGID,CATALOGMOVEMENT.LOCATIONID ORDER BY CATALOGMOVEMENTID DESC rows unbounded preceding) AS stock_quantite_debut,
|
|
|
qte_fin-SUM(MOVEMENTQUANTITY) OVER (PARTITION BY CATALOGMOVEMENT.CATALOGID,CATALOGMOVEMENT.LOCATIONID ORDER BY CATALOGMOVEMENTID DESC rows unbounded preceding) + MOVEMENTQUANTITY AS stock_quantite_fin,
|
|
|
COALESCE(LEAD(MOVEMENTDATETIME) OVER (PARTITION BY CATALOGMOVEMENT.CATALOGID ORDER BY MOVEMENTDATETIME),'2099-12-31') AS date_fin,
|
|
|
CASE WHEN date_trunc('day',(LAG(MOVEMENTDATETIME) OVER (PARTITION BY CATALOGMOVEMENT.CATALOGID,CATALOGMOVEMENT.LOCATIONID ORDER BY MOVEMENTDATETIME))) != date_trunc('day',MOVEMENTDATETIME) THEN 1 ELSE 0 END AS est_premier_jour,
|
|
|
CASE WHEN date_trunc('day',(LEAD(MOVEMENTDATETIME) OVER (PARTITION BY CATALOGMOVEMENT.CATALOGID,CATALOGMOVEMENT.LOCATIONID ORDER BY MOVEMENTDATETIME))) != date_trunc('day',MOVEMENTDATETIME) THEN 1 ELSE 0 END AS est_dernier_jour,
|
|
|
no_sejour
|
|
|
FROM w_CATALOGMOVEMENT CATALOGMOVEMENT
|
|
|
LEFT JOIN prod_optim.CATALOGSTOCK ON CATALOGSTOCK.CATALOGSTOCKID = CATALOGMOVEMENT.CATALOGSTOCKID
|
|
|
LEFT JOIN w_STOCK_FIN ON CATALOGMOVEMENT.LOCATIONID = w_STOCK_FIN.LOCATIONID
|
|
|
AND CATALOGMOVEMENT.CATALOGID = w_STOCK_FIN.CATALOGID
|
|
|
LEFT JOIN prod_optim.USERS ON CATALOGMOVEMENT.WHOUPDATED = USERID
|
|
|
LEFT JOIN eco.t_types_mouvements ON MOVEMENTID = t_types_mouvements.code_original
|
|
|
LEFT JOIN eco.t_gestionnaires ON PERSONNELID = t_gestionnaires.code_original
|
|
|
LEFT JOIN eco.t_lieux ON CATALOGMOVEMENT.LOCATIONID = t_lieux.code_original
|
|
|
LEFT JOIN eco.t_unites_fonctionnelles ON 0 = t_unites_fonctionnelles.code_original
|
|
|
LEFT JOIN eco.t_articles ON CATALOGMOVEMENT.CATALOGID = t_articles.code_original
|
|
|
LEFT JOIN eco.t_sites ON SITEID = t_sites.code_original
|
|
|
WHERE MOVEMENTDATETIME >= date('[ENV_ECO_ANNEEDEBUT]-01-01')
|
|
|
ORDER BY CATALOGMOVEMENTID;
|
|
|
|
|
|
-- tva
|
|
|
DROP TABLE IF EXISTS w_tva;
|
|
|
CREATE TEMP TABLE w_tva AS
|
|
|
SELECT
|
|
|
CATALOGID,
|
|
|
UNITCOSTVAT::numeric/100 AS tx_tva,
|
|
|
date(DELIVERYDATE) AS DELIVERYDATE,
|
|
|
date(CASE WHEN lead(DELIVERYDATE) OVER (PARTITION BY CATALOGID ORDER BY DELIVERYDATE) IS NOT NULL THEN
|
|
|
lead(DELIVERYDATE) OVER (PARTITION BY CATALOGID ORDER BY DELIVERYDATE) ELSE '2099-12-31' END) AS next_DELIVERYDATE,
|
|
|
date(CASE WHEN lag(DELIVERYDATE) OVER (PARTITION BY CATALOGID ORDER BY DELIVERYDATE) IS NOT NULL THEN
|
|
|
lag(DELIVERYDATE) OVER (PARTITION BY CATALOGID ORDER BY DELIVERYDATE) ELSE '1900-01-01' END) AS prev_DELIVERYDATE
|
|
|
FROM
|
|
|
prod_optim.BLOCDELIVERYLINE JOIN prod_optim.BLOCDELIVERY ON BLOCDELIVERYLINE.DELIVERYID = BLOCDELIVERY.DELIVERYID
|
|
|
;
|
|
|
|
|
|
UPDATE eco.p_mouvements_articles
|
|
|
SET
|
|
|
entree_montant_ht = prix_unitaire*entree_quantite,
|
|
|
entree_montant = prix_unitaire*entree_quantite*(1+tx_tva),
|
|
|
sortie_montant_ht = prix_unitaire*sortie_quantite,
|
|
|
sortie_montant = prix_unitaire*sortie_quantite*(1+tx_tva)
|
|
|
FROM w_tva, eco.t_articles
|
|
|
WHERE
|
|
|
t_articles.oid = article_id AND
|
|
|
CATALOGID = t_articles.code_original AND
|
|
|
date BETWEEN DELIVERYDATE AND next_DELIVERYDATE
|
|
|
;
|
|
|
|
|
|
UPDATE eco.p_mouvements_articles
|
|
|
SET
|
|
|
entree_montant_ht = prix_unitaire*entree_quantite,
|
|
|
entree_montant = prix_unitaire*entree_quantite*(1+tx_tva),
|
|
|
sortie_montant_ht = prix_unitaire*sortie_quantite,
|
|
|
sortie_montant = prix_unitaire*entree_quantite*(1+tx_tva)
|
|
|
FROM w_tva, eco.t_articles
|
|
|
WHERE
|
|
|
t_articles.oid = article_id AND
|
|
|
CATALOGID = t_articles.code_original AND
|
|
|
date BETWEEN prev_DELIVERYDATE AND DELIVERYDATE AND
|
|
|
entree_montant = 0 AND sortie_montant = 0
|
|
|
;
|
|
|
|
|
|
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');
|
|
|
|
|
|
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';
|
|
|
|
|
|
-- Déterminer la ligne de commande
|
|
|
ANALYSE eco.p_mouvements_articles
|
|
|
;
|
|
|
|
|
|
-- Règle 1 = Si une ligne pour un article, tous les mouvements de cet article sont associés à cette ligne
|
|
|
UPDATE eco.p_mouvements_articles
|
|
|
SET ligne_commande = subview.ligne_commande
|
|
|
FROM
|
|
|
(
|
|
|
SELECT commande_id, article_id, MIN(ligne_commande) AS ligne_commande
|
|
|
FROM eco.p_lignes_commandes
|
|
|
GROUP BY 1,2
|
|
|
HAVING count(*) = 1
|
|
|
) subview
|
|
|
WHERE p_mouvements_articles.commande_id = subview.commande_id AND
|
|
|
p_mouvements_articles.article_id = subview.article_id AND
|
|
|
p_mouvements_articles.ligne_commande = 0
|
|
|
;
|
|
|
|
|
|
-- Règle 2 = Il y a plusieurs lignes pour le même article dans la commande, On analyse les quantités progressives pour attribuer
|
|
|
DROP TABLE IF EXISTS w_lignes_commande_reste;
|
|
|
CREATE TEMP TABLE w_lignes_commande_reste AS
|
|
|
SELECT *,
|
|
|
COALESCE(LAG(quantite_fin) OVER (PARTITION BY commande_id, article_id ORDER BY ligne_commande),0) AS quantite_debut
|
|
|
FROM
|
|
|
(
|
|
|
SELECT p_lignes_commandes.commande_id, p_lignes_commandes.article_id, p_lignes_commandes.ligne_commande,
|
|
|
SUM(quantite_approvisionnement) OVER (PARTITION BY p_lignes_commandes.commande_id, p_lignes_commandes.article_id ORDER BY p_lignes_commandes.ligne_commande) AS quantite_fin
|
|
|
FROM eco.p_lignes_commandes
|
|
|
LEFT JOIN eco.p_mouvements_articles ON
|
|
|
p_lignes_commandes.commande_id = p_mouvements_articles.commande_id AND
|
|
|
p_lignes_commandes.ligne_commande = p_mouvements_articles.ligne_commande
|
|
|
WHERE p_mouvements_articles.oid IS NULL
|
|
|
) subview
|
|
|
;
|
|
|
|
|
|
DROP TABLE IF EXISTS w_mouvements_articles_reste;
|
|
|
CREATE TEMP TABLE w_mouvements_articles_reste AS
|
|
|
SELECT *,
|
|
|
COALESCE(LAG(quantite_fin) OVER (PARTITION BY commande_id, article_id ORDER BY oid),0) AS quantite_debut
|
|
|
FROM
|
|
|
(
|
|
|
SELECT commande_id, article_id, oid, entree_quantite-sortie_quantite AS quantite,
|
|
|
SUM(entree_quantite-sortie_quantite) OVER (PARTITION BY commande_id, article_id ORDER BY sens_mouvement,oid) AS quantite_fin
|
|
|
FROM eco.p_mouvements_articles where commande_id <> 0 AND ligne_commande = 0
|
|
|
) subview
|
|
|
;
|
|
|
|
|
|
UPDATE eco.p_mouvements_articles
|
|
|
SET ligne_commande = subview.ligne_commande
|
|
|
FROM
|
|
|
(
|
|
|
SELECT w_mouvements_articles_reste.oid, w_lignes_commande_reste.ligne_commande
|
|
|
FROM w_mouvements_articles_reste
|
|
|
JOIN w_lignes_commande_reste ON
|
|
|
w_mouvements_articles_reste.commande_id = w_lignes_commande_reste.commande_id AND
|
|
|
w_mouvements_articles_reste.article_id = w_lignes_commande_reste.article_id
|
|
|
WHERE (
|
|
|
w_mouvements_articles_reste.quantite_fin > w_lignes_commande_reste.quantite_debut AND
|
|
|
w_mouvements_articles_reste.quantite_fin <= w_lignes_commande_reste.quantite_fin
|
|
|
)
|
|
|
) subview
|
|
|
WHERE p_mouvements_articles.oid = subview.oid
|
|
|
;
|
|
|
|
|
|
|
|
|
]]></sqlcmd>
|
|
|
</NODE>
|
|
|
|
|
|
<NODE label="Stocks">
|
|
|
<sqlcmd><![CDATA[
|
|
|
-- stocks
|
|
|
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');
|
|
|
|
|
|
|
|
|
|
|
|
-- insertion
|
|
|
TRUNCATE eco.p_stock
|
|
|
;
|
|
|
|
|
|
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');
|
|
|
|
|
|
-- etat des mouvements
|
|
|
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_fin
|
|
|
)
|
|
|
SELECT
|
|
|
article_id,
|
|
|
compte_id,
|
|
|
ucd_id,
|
|
|
lpp_id,
|
|
|
site_id,
|
|
|
lieu_id,
|
|
|
date_trunc('month',date),
|
|
|
date_trunc('month',date) + interval '1 month' - interval '1 day',
|
|
|
SUM(entree_quantite),
|
|
|
SUM(entree_montant_ht),
|
|
|
SUM(sortie_quantite),
|
|
|
SUM(sortie_montant),
|
|
|
(MAX(ARRAY[oid,prix_unitaire]))[2] AS pump,
|
|
|
(MIN(ARRAY[oid,stock_quantite_debut]))[2] AS stock_quantite_debut,
|
|
|
(MIN(ARRAY[oid,stock_quantite_fin]))[2] AS stock_quantite_fin,
|
|
|
(MIN(ARRAY[oid,stock_quantite_debut]))[2] *(MIN(ARRAY[oid,prix_unitaire]))[2] AS stock_valeur_debut,
|
|
|
(MAX(ARRAY[oid,stock_quantite_fin]))[2] *(MAX(ARRAY[oid,prix_unitaire]))[2] AS stock_valeur_fin
|
|
|
FROM eco.p_mouvements_articles
|
|
|
WHERE date_trunc('month',date) > '[ENV_ECO_ANNEEDEBUT]-01-01'
|
|
|
GROUP BY 1,2,3,4,5,6,7,8
|
|
|
;
|
|
|
|
|
|
VACUUM ANALYSE eco.p_stock;
|
|
|
|
|
|
-- ajout des stocks mensuels manquants
|
|
|
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_fin
|
|
|
)
|
|
|
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
|
|
|
FROM eco.p_stock
|
|
|
LEFT JOIN eco.p_stock p_stock_prev ON
|
|
|
p_stock.site_id = p_stock_prev.site_id AND
|
|
|
p_stock.lieu_id = p_stock_prev.lieu_id AND
|
|
|
p_stock.article_id = p_stock_prev.article_id AND
|
|
|
date(date_trunc(''month'',p_stock.date_debut) - interval ''1 day'') = p_stock_prev.date_fin
|
|
|
WHERE
|
|
|
p_stock.date_debut <= now() AND
|
|
|
p_stock.date_fin >= ''[ENV_ECO_ANNEEDEBUT]-01-01'' AND
|
|
|
p_stock.stock_quantite_debut != 0 AND
|
|
|
p_stock_prev.article_id IS NULL
|
|
|
',200)
|
|
|
;
|
|
|
|
|
|
VACUUM ANALYSE eco.p_stock;
|
|
|
|
|
|
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_fin
|
|
|
)
|
|
|
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
|
|
|
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]-01-01'' AND
|
|
|
p_stock.stock_quantite_fin != 0 AND
|
|
|
p_stock_next.article_id IS NULL
|
|
|
',200)
|
|
|
;
|
|
|
|
|
|
SELECT base.cti_enable_index('eco', 'i_stock_1');
|
|
|
SELECT base.cti_enable_index('eco', 'i_stock_2');
|
|
|
SELECT base.cti_enable_index('eco', 'i_stock_3');
|
|
|
SELECT base.cti_enable_index('eco', 'i_stock_4');
|
|
|
SELECT base.cti_enable_index('eco', 'i_stock_5');
|
|
|
]]></sqlcmd>
|
|
|
</NODE>
|
|
|
|
|
|
|
|
|
<NODE label="Chiffrier">
|
|
|
<sqlcmd><![CDATA[
|
|
|
TRUNCATE eco.p_chiffrier_production;
|
|
|
|
|
|
INSERT INTO eco.p_chiffrier_production (mois)
|
|
|
SELECT extract('year' FROM date) * 100 + extract('month' FROM date)
|
|
|
FROM eco.p_mouvements_articles
|
|
|
GROUP BY 1;
|
|
|
|
|
|
]]></sqlcmd>
|
|
|
</NODE>
|
|
|
</NODE>
|
|
|
<NODE name="POST" label="POST-TRAITEMENTS">
|
|
|
<sqlcmd><![CDATA[
|
|
|
VACUUM ANALYSE eco.p_mouvements_articles;
|
|
|
VACUUM ANALYSE eco.p_stock;
|
|
|
|
|
|
SELECT eco.cti_update_mvt_qte_stock();
|
|
|
SELECT eco.cti_update_mvt_mnt_stock();
|
|
|
|
|
|
SELECT eco.cti_reorganize_sejour();
|
|
|
SELECT eco.cti_reorganize_sejour_ucd_lpp();
|
|
|
]]></sqlcmd>
|
|
|
</NODE>
|
|
|
|
|
|
</ROOT>
|