|
|
<?xml version="1.0" encoding="ISO-8859-1"?>
|
|
|
<ROOT>
|
|
|
<NODE name="INIT" label="INITIALISATIONS">
|
|
|
|
|
|
<NODE label="Tests initiaux">
|
|
|
<sqlcmd><![CDATA[
|
|
|
CTISELECT_PROPERTY_READ 'HAS_CIOSPECIALITE', count(*)
|
|
|
FROM information_schema.columns
|
|
|
WHERE table_schema = 'prod_pharma' AND table_name = 'ciospecialite' AND column_name = 'codeucd';
|
|
|
|
|
|
]]></sqlcmd>
|
|
|
</NODE>
|
|
|
|
|
|
<NODE label="Préparation">
|
|
|
<sqlcmd><![CDATA[
|
|
|
-- Type de commandes autorisées
|
|
|
INSERT INTO eco.t_divers (code, texte, valeur, description)
|
|
|
SELECT
|
|
|
'PHARMA_COM_TO_SYNC',
|
|
|
'Type de commande à remonter (défaut 2,3,4)',
|
|
|
'2,3,4',
|
|
|
'1-Commandes en préparation, 2-commandes validées, 3- commandes en cours, 4-commandes soldées, 5-commandes annulées, 6-?'
|
|
|
WHERE 'PHARMA_COM_TO_SYNC' NOT IN (SELECT code FROM eco.t_divers)
|
|
|
;
|
|
|
|
|
|
DROP TABLE IF EXISTS w_COMMANDE;
|
|
|
CREATE TEMP TABLE w_COMMANDE AS
|
|
|
SELECT COMMANDE.*,
|
|
|
'0'::text AS is_double,
|
|
|
NULL::numeric[] AS PRCLEUNIK_array
|
|
|
FROM prod_pharma.COMMANDE
|
|
|
LEFT JOIN prod_pharma.MAGASIN ON MAGASIN = CODEMAGASIN
|
|
|
WHERE (IDMAGASIN = ANY (string_to_array('[ETAB_ID]'::text,',')) OR '[ETAB_ID]' = '' OR '[ETAB_ID]' = '-1')
|
|
|
AND (DATECMDE BETWEEN '[ENV_ECO_ANNEEDEBUT]0101' AND now() OR
|
|
|
DATELIVCMD BETWEEN '[ENV_ECO_ANNEEDEBUT]0101' AND now() OR
|
|
|
DATESAISIEFACT BETWEEN '[ENV_ECO_ANNEEDEBUT]0101' AND now())
|
|
|
AND NUMCMDE > 0 AND
|
|
|
ETATCMDE = ANY(ARRAY[(SELECT string_to_array(valeur,',') FROM eco.t_divers WHERE code = 'PHARMA_COM_TO_SYNC')])
|
|
|
;
|
|
|
|
|
|
ANALYSE w_COMMANDE
|
|
|
;
|
|
|
|
|
|
-- Attention, il peut y avoir quelques doubles dans les numeros de commandes
|
|
|
-- Et cela provoque des doubles dans les mouvements de livraison
|
|
|
-- Solution : pour ces commandes en double, identifier les produits pour mieux filtrer sur les mouvements (MVTPDT) plus loin
|
|
|
-- Si un produit est dans deux commandes, on en choisit une
|
|
|
UPDATE w_COMMANDE
|
|
|
SET is_double = '1'
|
|
|
FROM
|
|
|
(
|
|
|
SELECT NUMCMDE, SUFCMDE
|
|
|
FROM w_COMMANDE
|
|
|
GROUP BY 1,2
|
|
|
HAVING count(*) > 1
|
|
|
) subview
|
|
|
WHERE w_COMMANDE.NUMCMDE = subview.NUMCMDE AND
|
|
|
w_COMMANDE.SUFCMDE = subview.SUFCMDE
|
|
|
;
|
|
|
|
|
|
UPDATE w_COMMANDE
|
|
|
SET PRCLEUNIK_array = subview.PRCLEUNIK_array
|
|
|
FROM
|
|
|
(
|
|
|
SELECT C1CLEUNIK,
|
|
|
base.cti_array_accum(DISTINCT PRCLEUNIK) AS PRCLEUNIK_array
|
|
|
FROM
|
|
|
(
|
|
|
SELECT NUMCMDE,
|
|
|
SUFCMDE,
|
|
|
PRCLEUNIK,
|
|
|
MIN(w_COMMANDE.C1CLEUNIK) AS C1CLEUNIK
|
|
|
FROM w_COMMANDE
|
|
|
JOIN prod_pharma.LIGNE ON w_COMMANDE.C1CLEUNIK = LIGNE.C1CLEUNIK
|
|
|
WHERE is_double = '1'
|
|
|
GROUP BY 1,2,3
|
|
|
) subview
|
|
|
GROUP BY 1
|
|
|
) subview
|
|
|
WHERE w_COMMANDE.C1CLEUNIK = subview.C1CLEUNIK
|
|
|
;
|
|
|
|
|
|
SELECT base.cti_execute(
|
|
|
'ALTER TABLE w_COMMANDE ADD COLUMN C_EDI_NUMCOMMANDE text DEFAULT ''''',
|
|
|
1
|
|
|
)
|
|
|
WHERE 'C_EDI_NUMCOMMANDE' NOT IN (SELECT upper(column_name) FROM information_schema.columns WHERE table_name = 'w_commande')
|
|
|
;
|
|
|
|
|
|
CREATE INDEX w_COMMANDE_i1 ON w_COMMANDE USING btree(C1CLEUNIK);
|
|
|
CREATE INDEX w_COMMANDE_i2 ON w_COMMANDE USING btree(F0CLEUNIK);
|
|
|
|
|
|
DROP TABLE IF EXISTS w_LIGNE_source;
|
|
|
CREATE TEMP TABLE w_LIGNE_source AS
|
|
|
SELECT LIGNE.*, row_number() OVER () AS LIGNE_sequence
|
|
|
FROM prod_pharma.LIGNE
|
|
|
JOIN w_COMMANDE ON w_COMMANDE.C1CLEUNIK = LIGNE.C1CLEUNIK
|
|
|
;
|
|
|
|
|
|
ANALYSE w_LIGNE_source
|
|
|
;
|
|
|
|
|
|
UPDATE w_LIGNE_source
|
|
|
SET SERVICE = UPPER(SERVICE)
|
|
|
WHERE SERVICE <> UPPER(SERVICE) AND
|
|
|
UPPER(SERVICE) IN (SELECT SERVICE FROM prod_pharma.SERVICE)
|
|
|
;
|
|
|
|
|
|
CREATE INDEX i_w_LIGNE_source_L0CLEUNIK ON w_LIGNE_source USING btree (L0CLEUNIK)
|
|
|
;
|
|
|
CREATE INDEX i_w_LIGNE_source_C1CLEUNIK ON w_LIGNE_source USING btree (C1CLEUNIK)
|
|
|
;
|
|
|
CREATE INDEX i_w_LIGNE_source_PRCLEUNIK ON w_LIGNE_source USING btree (PRCLEUNIK)
|
|
|
;
|
|
|
|
|
|
DELETE FROM w_LIGNE_source
|
|
|
USING
|
|
|
(
|
|
|
SELECT L0CLEUNIK, (MAX(ARRAY[C1INIT,LIGNE_sequence::text]))[2]::numeric AS keep_sequence
|
|
|
FROM w_LIGNE_source
|
|
|
GROUP BY 1
|
|
|
HAVING count(*) > 1
|
|
|
) subview
|
|
|
WHERE w_LIGNE_source.L0CLEUNIK = subview.L0CLEUNIK AND
|
|
|
w_LIGNE_source.LIGNE_sequence <> keep_sequence
|
|
|
;
|
|
|
|
|
|
-- Problème de lignes dupliquées sur les commandes
|
|
|
UPDATE w_LIGNE_source
|
|
|
SET NOLIGCMDE = NOLIGCMDE_new
|
|
|
FROM
|
|
|
(
|
|
|
SELECT w_LIGNE_source.C1CLEUNIK, w_LIGNE_source.L0CLEUNIK, NOLIGCMDE, row_number() OVER (PARTITION BY w_LIGNE_source.C1CLEUNIK ORDER BY w_LIGNE_source.L0CLEUNIK) AS NOLIGCMDE_new
|
|
|
FROM w_LIGNE_source
|
|
|
JOIN
|
|
|
(
|
|
|
SELECT C1CLEUNIK
|
|
|
FROM
|
|
|
(
|
|
|
SELECT C1CLEUNIK, NOLIGCMDE
|
|
|
FROM w_LIGNE_source
|
|
|
GROUP BY 1,2
|
|
|
HAVING count(*) > 1
|
|
|
) subview
|
|
|
GROUP BY 1
|
|
|
) subview ON w_LIGNE_source.C1CLEUNIK = subview.C1CLEUNIK
|
|
|
) subview
|
|
|
WHERE w_LIGNE_source.L0CLEUNIK = subview.L0CLEUNIK
|
|
|
;
|
|
|
|
|
|
|
|
|
DROP SEQUENCE IF EXISTS w_MVTPDT_sequence;
|
|
|
CREATE TEMP SEQUENCE w_MVTPDT_sequence;
|
|
|
|
|
|
|
|
|
DROP TABLE IF EXISTS w_MVTPDT;
|
|
|
CREATE TEMP TABLE w_MVTPDT AS
|
|
|
SELECT
|
|
|
COALESCE(CODEMAGASIN,'') AS MAGASIN,
|
|
|
MVTPDT.MVTCLEUNIK,
|
|
|
MVTPDT.PRCLEUNIK,
|
|
|
MVTPDT.F0CLEUNIK,
|
|
|
MVTPDT.DATEMVT,
|
|
|
MVTPDT.TYPEMVT,
|
|
|
MVTPDT.TYPESORTIE,
|
|
|
MVTPDT.VALTTC,
|
|
|
MVTPDT.VALHT,
|
|
|
CASE WHEN MAGASINDEST = '' THEN MVTPDT.SENSMVT
|
|
|
WHEN MAGASINDEST = CODEMAGASIN THEN 1
|
|
|
ELSE 2 END AS SENSMVT,
|
|
|
MVTPDT.CODE_UCD,
|
|
|
MVTPDT.REFMVT1,
|
|
|
MVTPDT.REFMVT2,
|
|
|
MVTPDT.REFMVT3,
|
|
|
MVTPDT.MOTIF,
|
|
|
MVTPDT.L0CLEUNIK,
|
|
|
MVTPDT.CODE_LPP,
|
|
|
MVTPDT.SERVICE,
|
|
|
MVTPDT.QUANTITE,
|
|
|
nextval('w_MVTPDT_sequence'::regclass) AS oid,
|
|
|
COALESCE(w_COMMANDE.C1CLEUNIK,0) AS C1CLEUNIK,
|
|
|
CASE WHEN MVTPDT.SERVICE <> '' AND MVTPDT.SERVICE <> '-1' THEN '|' || MVTPDT.SERVICE ELSE '' END AS profil_code_original,
|
|
|
''::text AS no_patient,
|
|
|
''::text AS no_sejour
|
|
|
FROM prod_pharma.MVTPDT
|
|
|
LEFT JOIN w_COMMANDE ON
|
|
|
NUMCMDE::text || SUFCMDE::text = REFMVT1 AND
|
|
|
NUMCMDE > 0 AND
|
|
|
TYPEMVT IN (1,3) AND
|
|
|
ETATCMDE <> '5' AND
|
|
|
(is_double = '0' OR MVTPDT.PRCLEUNIK = ANY(PRCLEUNIK_array))
|
|
|
LEFT JOIN prod_pharma.MAGASIN ON MVTPDT.MAGASIN = CODEMAGASIN OR MAGASINDEST = CODEMAGASIN
|
|
|
WHERE DATEMVT BETWEEN '[ENV_ECO_ANNEEDEBUT]0101' AND now() AND TYPEMVT <> 3
|
|
|
AND (IDMAGASIN = ANY (string_to_array('[ETAB_ID]'::text,',')) OR '[ETAB_ID]' = '' OR '[ETAB_ID]' = '-1')
|
|
|
GROUP BY 1,2,3,4,5,6,7,8,9,10,11,12,13,14,15,16,17,18,19,20,21,22;
|
|
|
|
|
|
ANALYSE w_MVTPDT
|
|
|
;
|
|
|
|
|
|
|
|
|
CREATE INDEX w_MVTPDT_i1 ON w_MVTPDT USING btree (oid);
|
|
|
CREATE INDEX w_MVTPDT_i2 ON w_MVTPDT USING btree (C1CLEUNIK);
|
|
|
CREATE INDEX w_MVTPDT_i3 ON w_MVTPDT USING btree (L0CLEUNIK);
|
|
|
CREATE INDEX w_MVTPDT_14 ON w_MVTPDT USING btree (PRCLEUNIK);
|
|
|
CREATE INDEX w_MVTPDT_i5 ON w_MVTPDT USING btree (F0CLEUNIK);
|
|
|
|
|
|
UPDATE w_MVTPDT
|
|
|
SET SERVICE = UPPER(SERVICE)
|
|
|
WHERE SERVICE <> UPPER(SERVICE) AND
|
|
|
UPPER(SERVICE) IN (SELECT SERVICE FROM prod_pharma.SERVICE)
|
|
|
;
|
|
|
|
|
|
-- Si premier mouvement = inventaire, il doit être considéré comme une entrée
|
|
|
UPDATE w_MVTPDT SET
|
|
|
SENSMVT = 1,
|
|
|
TYPEMVT = 1,
|
|
|
QUANTITE = 0 - QUANTITE,
|
|
|
VALHT = 0 - VALHT,
|
|
|
VALTTC = 0 - VALTTC
|
|
|
FROM
|
|
|
(
|
|
|
SELECT MAGASIN, PRCLEUNIK,
|
|
|
(MIN(ARRAY[to_char(MVTCLEUNIK,'FM000000000000000'),TYPESORTIE]))[2],
|
|
|
MIN(MVTCLEUNIK) AS MVTCLEUNIK
|
|
|
FROM w_MVTPDT
|
|
|
GROUP BY 1,2
|
|
|
HAVING (MIN(ARRAY[to_char(MVTCLEUNIK,'FM000000000000000'),TYPESORTIE]))[2] = 'IN'
|
|
|
) subview
|
|
|
WHERE w_MVTPDT.MVTCLEUNIK = subview.MVTCLEUNIK
|
|
|
;
|
|
|
|
|
|
-- Inverser les retours
|
|
|
UPDATE w_MVTPDT SET
|
|
|
QUANTITE = 0-QUANTITE,
|
|
|
VALHT = 0-VALHT,
|
|
|
VALTTC = 0-VALTTC
|
|
|
WHERE SENSMVT = 1 AND
|
|
|
TYPEMVT IN (4,5)
|
|
|
;
|
|
|
|
|
|
-- Forcage des magasins en tant que lieu
|
|
|
INSERT INTO eco.t_divers (code, texte, valeur, description)
|
|
|
SELECT
|
|
|
'PHARMA_MAG_LIEU',
|
|
|
'Forcer les magasins en tant que lieu',
|
|
|
'0',
|
|
|
'0=Non 1=Oui'
|
|
|
WHERE 'PHARMA_MAG_LIEU' NOT IN (SELECT code FROM eco.t_divers)
|
|
|
;
|
|
|
|
|
|
-- Sejours et patients
|
|
|
UPDATE w_MVTPDT SET
|
|
|
no_patient = subview.no_patient,
|
|
|
no_sejour = subview.no_sejour
|
|
|
FROM
|
|
|
(
|
|
|
SELECT NUMBONDISP, PRCLEUNIK, date(DATECNSPAT) AS DATECNSPAT, count(distinct CONSOPAT.PACLEUNIK),
|
|
|
MAX(COALESCE(PATIENT2.DOSSIER,PATIENT.DOSSIER,''))::text AS no_patient,
|
|
|
MAX(COALESCE(SEJOUR.ADMISSION,''))::text AS no_sejour
|
|
|
FROM prod_pharma.CONSOPAT
|
|
|
LEFT JOIN prod_pharma.PATIENT ON CONSOPAT.PACLEUNIK = PATIENT.PACLEUNIK
|
|
|
LEFT JOIN prod_pharma.SEJOUR ON CONSOPAT.SECLEUNIK = SEJOUR.SECLEUNIK
|
|
|
LEFT JOIN prod_pharma.PATIENT PATIENT2 ON SEJOUR.PACLEUNIK = PATIENT2.PACLEUNIK
|
|
|
GROUP BY 1,2,3
|
|
|
HAVING count(distinct CONSOPAT.PACLEUNIK) = 1
|
|
|
) subview
|
|
|
WHERE w_MVTPDT.REFMVT3 = subview.NUMBONDISP AND
|
|
|
date(w_MVTPDT.DATEMVT) = subview.DATECNSPAT AND
|
|
|
w_MVTPDT.PRCLEUNIK = subview.PRCLEUNIK
|
|
|
;
|
|
|
|
|
|
]]></sqlcmd>
|
|
|
</NODE>
|
|
|
|
|
|
<NODE label="Tables Articles">
|
|
|
|
|
|
<NODE label="" comment="UCD si table récupérée par aspirateur">
|
|
|
<condition><![CDATA[
|
|
|
"[HAS_CIOSPECIALITE]" != "0"
|
|
|
]]></condition>
|
|
|
<sqlcmd><![CDATA[
|
|
|
-- UCD
|
|
|
INSERT INTO base.t_ucd(
|
|
|
code,
|
|
|
texte,
|
|
|
texte_court,
|
|
|
laboratoire_texte,
|
|
|
conditionnement_texte,
|
|
|
atc_code,
|
|
|
atc_texte,
|
|
|
ephmra_code, ephmra_texte,
|
|
|
prestation_defaut_id)
|
|
|
SELECT
|
|
|
CODEUCD,
|
|
|
NOMCOMMERCIAL,
|
|
|
LIBRAC,
|
|
|
LIBFAB,
|
|
|
'',
|
|
|
'',
|
|
|
'',
|
|
|
'',
|
|
|
'',
|
|
|
0
|
|
|
FROM prod_pharma.CIOSPECIALITE
|
|
|
WHERE CODEUCD > 0 AND CODEUCD NOT IN (SELECT code FROM base.t_ucd);
|
|
|
|
|
|
]]></sqlcmd>
|
|
|
</NODE>
|
|
|
|
|
|
<sqlcmd><![CDATA[
|
|
|
|
|
|
-- LPP
|
|
|
INSERT INTO base.t_lpp(
|
|
|
code,
|
|
|
texte,
|
|
|
texte_court)
|
|
|
SELECT
|
|
|
CODELPP,
|
|
|
CASE WHEN CODELPP <> '' THEN LIBELLPP ELSE CODELPP END,
|
|
|
CASE WHEN CODELPP <> '' THEN LIBELLPP ELSE CODELPP END
|
|
|
FROM prod_pharma.LPP
|
|
|
WHERE CODELPP > 0 AND CODELPP NOT IN (SELECT code FROM base.t_lpp);
|
|
|
|
|
|
|
|
|
-- comptes
|
|
|
INSERT INTO eco.t_compte(code, texte, texte_court, code_original)
|
|
|
SELECT COMPTE, MAX(LIBCOMPTE), MAX(LIBCOMPTE), COMPTE
|
|
|
FROM prod_pharma.compte
|
|
|
WHERE COMPTE <> '-1' AND
|
|
|
COMPTE <> '1' AND
|
|
|
COMPTE <> '' AND
|
|
|
COMPTE NOT IN (SELECT code_original FROM eco.t_compte WHERE code_original IS NOT NULL) AND
|
|
|
COMPTE IN (SELECT COMPTE FROM prod_pharma.PRODUIT WHERE COMPTE IS NOT NULL)
|
|
|
GROUP BY 1
|
|
|
ORDER BY 1;
|
|
|
|
|
|
|
|
|
|
|
|
INSERT INTO eco.t_compte(code, texte, texte_court, code_original)
|
|
|
SELECT COMPTE, MAX(LIBCOMPTE), MAX(LIBCOMPTE), COMPTE
|
|
|
FROM prod_pharma.compte
|
|
|
WHERE COMPTE <> '-1' AND
|
|
|
COMPTE <> '1' AND
|
|
|
COMPTE <> '' AND
|
|
|
COMPTE NOT IN (SELECT code_original FROM eco.t_compte WHERE code_original IS NOT NULL) AND
|
|
|
COMPTE IN (SELECT COMPTE FROM prod_pharma.ACHATS WHERE COMPTE IS NOT NULL)
|
|
|
GROUP BY 1
|
|
|
ORDER BY 1;
|
|
|
|
|
|
UPDATE eco.t_compte
|
|
|
SET
|
|
|
texte = sub.texte,
|
|
|
texte_court = sub.texte_court
|
|
|
FROM (
|
|
|
SELECT
|
|
|
COMPTE,
|
|
|
MAX(LIBCOMPTE) AS texte,
|
|
|
LEFT(MAX(LIBCOMPTE),50) AS texte_court
|
|
|
FROM prod_pharma.COMPTE
|
|
|
GROUP BY 1
|
|
|
) sub
|
|
|
WHERE
|
|
|
COMPTE = code AND
|
|
|
(
|
|
|
t_compte.texte != sub.texte OR
|
|
|
t_compte.texte_court != sub.texte_court
|
|
|
)
|
|
|
;
|
|
|
|
|
|
|
|
|
INSERT INTO eco.t_classification_atc(code_original, code, texte, texte_court )
|
|
|
SELECT CLASSETH, MAX(CLASSETH), MAX(LIBELLE), MAX(LIBELLE)
|
|
|
FROM prod_PHARMA.CLASSETH
|
|
|
LEFT JOIN eco.t_classification_atc ON (code_original = CLASSETH)
|
|
|
WHERE CLASSETH NOT IN ('-1', '1', '') AND
|
|
|
code_original IS NULL
|
|
|
GROUP BY 1
|
|
|
ORDER BY 1;
|
|
|
|
|
|
UPDATE eco.t_classification_atc
|
|
|
SET texte = LIBELLE,
|
|
|
texte_court = LIBELLE
|
|
|
FROM prod_PHARMA.CLASSETH
|
|
|
WHERE
|
|
|
code_original = CLASSETH AND
|
|
|
(texte IS DISTINCT FROM LIBELLE OR
|
|
|
texte_court IS DISTINCT FROM LIBELLE);
|
|
|
|
|
|
|
|
|
-- Standard ATC
|
|
|
SELECT eco.cti_reorganize_classification_atc();
|
|
|
|
|
|
|
|
|
|
|
|
-- unités
|
|
|
|
|
|
INSERT INTO eco.t_unites(code_original, code, texte, texte_court )
|
|
|
SELECT UDCLEUNIK, MAX(CODEUD), MAX(LIBELUD), MAX(LIBELUD)
|
|
|
FROM prod_PHARMA.UNITEDOSE
|
|
|
LEFT JOIN eco.t_unites ON (code_original = UDCLEUNIK)
|
|
|
WHERE UDCLEUNIK NOT IN (0, 1 , -1) AND code_original IS NULL AND CODEUD <> ''
|
|
|
GROUP BY 1
|
|
|
ORDER BY 2;
|
|
|
|
|
|
UPDATE eco.t_unites
|
|
|
SET code = CODEUD,
|
|
|
texte = LIBELUD,
|
|
|
texte_court = LIBELUD
|
|
|
FROM prod_PHARMA.UNITEDOSE
|
|
|
WHERE
|
|
|
code_original = UDCLEUNIK AND
|
|
|
(code IS DISTINCT FROM CODEUD OR
|
|
|
texte IS DISTINCT FROM LIBELUD OR
|
|
|
texte_court IS DISTINCT FROM LIBELUD);
|
|
|
|
|
|
|
|
|
|
|
|
-- Types articles
|
|
|
|
|
|
INSERT INTO eco.t_types_articles(code_original, code, texte, texte_court )
|
|
|
SELECT substr(CODEPARAM,9), substr(CODEPARAM,9), MAX(VALPARAMTX), MAX(VALPARAMTX)
|
|
|
FROM prod_PHARMA.PARAMETR
|
|
|
LEFT JOIN eco.t_types_articles ON (code_original = substr(CODEPARAM,9))
|
|
|
WHERE CODEPARAM LIKE 'TTYPEPDT%' AND substr(CODEPARAM,9) BETWEEN '0' AND '9' AND VALPARAMTX <> '' AND code_original IS NULL
|
|
|
GROUP BY 1;
|
|
|
|
|
|
UPDATE eco.t_types_articles
|
|
|
SET texte = VALPARAMTX,
|
|
|
texte_court = VALPARAMTX
|
|
|
FROM prod_PHARMA.PARAMETR
|
|
|
WHERE CODEPARAM LIKE 'TTYPEPDT%' AND substr(CODEPARAM,9) BETWEEN '0' AND '9' AND VALPARAMTX <> '' AND
|
|
|
code_original = substr(CODEPARAM,9) AND
|
|
|
(texte IS DISTINCT FROM VALPARAMTX OR
|
|
|
texte_court IS DISTINCT FROM VALPARAMTX);
|
|
|
|
|
|
|
|
|
-- Catégories
|
|
|
|
|
|
INSERT INTO eco.t_categories_articles(code_original, code, texte, texte_court )
|
|
|
SELECT GRCLEUNIK, MAX(CODEGR), MAX(LIBELGR), MAX(LIBELGR)
|
|
|
FROM prod_PHARMA.GRPDT
|
|
|
LEFT JOIN eco.t_categories_articles ON (code_original = GRCLEUNIK)
|
|
|
WHERE GRCLEUNIK NOT IN (-1, 1) AND code_original IS NULL
|
|
|
GROUP BY 1;
|
|
|
|
|
|
UPDATE eco.t_categories_articles
|
|
|
SET texte = LIBELGR,
|
|
|
texte_court = LIBELGR
|
|
|
FROM prod_PHARMA.GRPDT
|
|
|
WHERE
|
|
|
code_original = GRCLEUNIK AND
|
|
|
(texte IS DISTINCT FROM LIBELGR OR
|
|
|
texte_court IS DISTINCT FROM LIBELGR);
|
|
|
|
|
|
|
|
|
-- Lieux
|
|
|
|
|
|
|
|
|
SELECT base.cti_execute('
|
|
|
INSERT INTO eco.t_lieux(code_original, code, texte, texte_court)
|
|
|
SELECT IDMAGASIN, CODEMAGASIN, MAX(LIBELLEMAGASIN), MAX(LIBELLEMAGASIN)
|
|
|
FROM prod_pharma.MAGASIN LEFT JOIN eco.t_lieux ON (code_original = IDMAGASIN)
|
|
|
WHERE code_original IS NULL
|
|
|
GROUP BY 1,2
|
|
|
ORDER BY 1,2
|
|
|
.,
|
|
|
|
|
|
UPDATE eco.t_lieux
|
|
|
SET texte = LIBELLEMAGASIN,
|
|
|
texte_court = LIBELLEMAGASIN
|
|
|
FROM prod_pharma.MAGASIN
|
|
|
WHERE code_original = IDMAGASIN
|
|
|
AND (texte IS DISTINCT FROM LIBELLEMAGASIN OR
|
|
|
texte_court IS DISTINCT FROM LIBELLEMAGASIN)
|
|
|
.,
|
|
|
',1)
|
|
|
WHERE (SELECT count(*) FROM eco.t_divers WHERE code = 'PHARMA_MAG_LIEU' AND valeur = '1') > 0;
|
|
|
|
|
|
SELECT base.cti_execute('
|
|
|
INSERT INTO eco.t_lieux(code_original, code, texte, texte_court)
|
|
|
SELECT LIEUSTOCK, LIEUSTOCK, MAX(LIBELLE), MAX(LIBELLE)
|
|
|
FROM prod_pharma.LIEUSTK LEFT JOIN eco.t_lieux ON (code_original = LIEUSTOCK)
|
|
|
WHERE LIEUSTOCK <> ''-1'' AND code_original IS NULL
|
|
|
GROUP BY 1
|
|
|
ORDER BY 1
|
|
|
.,
|
|
|
|
|
|
UPDATE eco.t_lieux
|
|
|
SET texte = LIBELLE,
|
|
|
texte_court = LIBELLE
|
|
|
FROM prod_pharma.LIEUSTK
|
|
|
WHERE code_original = LIEUSTOCK
|
|
|
AND (texte IS DISTINCT FROM LIBELLE OR
|
|
|
texte_court IS DISTINCT FROM LIBELLE)',1)
|
|
|
WHERE (SELECT count(*) FROM eco.t_divers WHERE code = 'PHARMA_MAG_LIEU' AND valeur = '1') = 0;
|
|
|
|
|
|
-- Sites
|
|
|
|
|
|
SELECT base.cti_execute('
|
|
|
INSERT INTO eco.t_sites(code_original, code, texte, texte_court)
|
|
|
SELECT IDMAGASIN, CODEMAGASIN, MAX(LIBELLEMAGASIN), MAX(LIBELLEMAGASIN)
|
|
|
FROM prod_pharma.MAGASIN LEFT JOIN eco.t_sites ON (code_original = IDMAGASIN)
|
|
|
WHERE code_original IS NULL
|
|
|
GROUP BY 1,2
|
|
|
ORDER BY 1,2.,
|
|
|
|
|
|
UPDATE eco.t_sites
|
|
|
SET texte = LIBELLEMAGASIN,
|
|
|
texte_court = LIBELLEMAGASIN
|
|
|
FROM prod_pharma.MAGASIN
|
|
|
WHERE code_original = IDMAGASIN
|
|
|
AND (texte IS DISTINCT FROM LIBELLEMAGASIN OR
|
|
|
texte_court IS DISTINCT FROM LIBELLEMAGASIN)
|
|
|
.,
|
|
|
',1)
|
|
|
WHERE (SELECT count(*) FROM eco.t_divers WHERE code = 'PHARMA_MAG_LIEU' AND valeur = '1') = 0
|
|
|
;
|
|
|
|
|
|
|
|
|
-- Articles
|
|
|
INSERT INTO eco.t_divers (code, texte, valeur, description)
|
|
|
SELECT
|
|
|
'PHARMA_CODE_ARTICLE',
|
|
|
'Sélection du code à remonter en tant que code article',
|
|
|
'0',
|
|
|
'0=Réference ou clé unique si référence vide 1=Clé unique'
|
|
|
WHERE 'PHARMA_CODE_ARTICLE' NOT IN (SELECT code FROM eco.t_divers)
|
|
|
;
|
|
|
|
|
|
DROP TABLE IF EXISTS w_PRODUIT;
|
|
|
CREATE TEMP TABLE w_PRODUIT AS
|
|
|
SELECT
|
|
|
PRCLEUNIK AS code_original,
|
|
|
CASE WHEN COALESCE(valeur,'0') = '0' THEN COALESCE(REFERENCE,to_char(PRCLEUNIK,'FM000000')) ELSE to_char(PRCLEUNIK,'FM000000') END AS code,
|
|
|
CASE WHEN LIBCALCPR <> '' THEN substr(LIBCALCPR, 1, 255) ELSE substr(PRNOM, 1, 255) END AS texte,
|
|
|
CASE WHEN LIBCALCPR <> '' THEN substr(LIBCALCPR, 1, 255) ELSE substr(PRNOM, 1, 255) END AS texte1,
|
|
|
substr(CASE WHEN NOMABREGE <> '' THEN NOMABREGE ELSE PRNOM END,1,50) AS texte_court,
|
|
|
PRODUIT.*
|
|
|
FROM prod_pharma.PRODUIT
|
|
|
LEFT JOIN eco.t_divers ON t_divers.code = 'PHARMA_CODE_ARTICLE'
|
|
|
WHERE PRCLEUNIK IN (select PRCLEUNIK from w_LIGNE_source LIGNE);
|
|
|
|
|
|
|
|
|
INSERT INTO w_PRODUIT
|
|
|
SELECT
|
|
|
PRCLEUNIK AS code_original,
|
|
|
CASE WHEN COALESCE(valeur,'0') = '0' THEN COALESCE(REFERENCE,to_char(PRCLEUNIK,'FM000000')) ELSE to_char(PRCLEUNIK,'FM000000') END AS code,
|
|
|
CASE WHEN LIBCALCPR <> '' THEN substr(LIBCALCPR, 1, 255) ELSE substr(PRNOM, 1, 255) END AS texte,
|
|
|
CASE WHEN LIBCALCPR <> '' THEN substr(LIBCALCPR, 1, 255) ELSE substr(PRNOM, 1, 255) END AS texte1,
|
|
|
substr(CASE WHEN NOMABREGE <> '' THEN NOMABREGE ELSE CASE WHEN LIBCALCPR <> '' THEN LIBCALCPR ELSE PRNOM END END,1,50) AS texte_court,
|
|
|
PRODUIT.*
|
|
|
FROM prod_pharma.PRODUIT
|
|
|
LEFT JOIN eco.t_divers ON t_divers.code = 'PHARMA_CODE_ARTICLE'
|
|
|
WHERE PRCLEUNIK IN (select PRCLEUNIK from w_MVTPDT) AND
|
|
|
PRCLEUNIK NOT IN (SELECT code_original FROM w_PRODUIT);
|
|
|
|
|
|
INSERT INTO eco.t_articles(code_original, code, texte, texte_court )
|
|
|
SELECT w_PRODUIT.code_original, w_PRODUIT.code, w_PRODUIT.texte, w_PRODUIT.texte_court
|
|
|
FROM w_PRODUIT
|
|
|
LEFT JOIN eco.t_articles ON (w_PRODUIT.code_original = t_articles.code_original)
|
|
|
WHERE t_articles.code_original IS NULL;
|
|
|
|
|
|
UPDATE eco.t_articles
|
|
|
SET
|
|
|
code = w_PRODUIT.code,
|
|
|
texte = w_PRODUIT.texte,
|
|
|
texte_court = w_PRODUIT.texte_court,
|
|
|
taux_tva_en_cours = round(COALESCE(VALPARAMRE,0)::numeric,1)
|
|
|
FROM w_PRODUIT
|
|
|
LEFT JOIN prod_pharma.PARAMETR ON CODEPARAM = 'RTVA'||TVA
|
|
|
WHERE w_PRODUIT.code_original = t_articles.code_original
|
|
|
AND (
|
|
|
t_articles.code IS DISTINCT FROM w_PRODUIT.code OR
|
|
|
t_articles.texte IS DISTINCT FROM w_PRODUIT.texte OR
|
|
|
t_articles.texte_court IS DISTINCT FROM w_PRODUIT.texte_court OR
|
|
|
taux_tva_en_cours IS DISTINCT FROM round(COALESCE(VALPARAMRE,0)::numeric,1)
|
|
|
)
|
|
|
;
|
|
|
|
|
|
|
|
|
UPDATE eco.t_articles
|
|
|
SET gere_en_stock = CASE WHEN MODEGEST IN (1,4) THEN '1' ELSE '0' END
|
|
|
FROM prod_pharma.PRODUIT
|
|
|
WHERE t_articles.code_original = PRODUIT.PRCLEUNIK AND
|
|
|
(gere_en_stock != CASE WHEN MODEGEST IN (1,4) THEN '1' ELSE '0' END)
|
|
|
;
|
|
|
|
|
|
UPDATE eco.t_articles
|
|
|
SET gere_en_stock = ''
|
|
|
WHERE gere_en_stock IS NULL;
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
UPDATE eco.t_articles SET
|
|
|
type_id = COALESCE(t_types_articles.oid,0),
|
|
|
famille_id = 0,
|
|
|
sous_famille_id = 0,
|
|
|
categorie_id = COALESCE(t_categories_articles.oid,0),
|
|
|
sous_categorie_id = 0,
|
|
|
unite_stockage_id = COALESCE(t_unites_stockage.oid,0),
|
|
|
unite_distribution_id = COALESCE(t_unites_distribution.oid,0)
|
|
|
FROM prod_pharma.PRODUIT
|
|
|
LEFT JOIN
|
|
|
(SELECT PRCLEUNIK, (MAX(ARRAY[MGPPRINC,GRCLEUNIK]))[2] AS GRCLEUNIK FROM prod_pharma.MULTIGRP WHERE GRCLEUNIK > 1 GROUP BY 1) MULTIGRP ON PRODUIT.PRCLEUNIK = MULTIGRP.PRCLEUNIK
|
|
|
LEFT JOIN eco.t_types_articles ON TYPEPDT = t_types_articles.code_original
|
|
|
LEFT JOIN eco.t_categories_articles ON MULTIGRP.GRCLEUNIK = t_categories_articles.code_original
|
|
|
LEFT JOIN eco.t_unites t_unites_stockage ON UDCLEUNIK = t_unites_stockage.code_original
|
|
|
LEFT JOIN eco.t_unites t_unites_distribution ON UDCLEUNIK = t_unites_distribution.code_original
|
|
|
WHERE
|
|
|
t_articles.code_original = PRODUIT.PRCLEUNIK AND
|
|
|
(
|
|
|
t_articles.type_id IS DISTINCT FROM COALESCE(t_types_articles.oid,0) OR
|
|
|
t_articles.categorie_id IS DISTINCT FROM COALESCE(t_categories_articles.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)
|
|
|
);
|
|
|
|
|
|
|
|
|
|
|
|
UPDATE eco.t_articles SET
|
|
|
classification_atc_id = (SELECT oid FROM eco.t_classification_atc WHERE code = 'Z99XX99')
|
|
|
FROM prod_pharma.PRODUIT
|
|
|
LEFT JOIN eco.t_classification_atc ON CLASSETH = t_classification_atc.code_original
|
|
|
WHERE
|
|
|
t_articles.code_original = PRCLEUNIK AND
|
|
|
t_classification_atc.oid IS NULL AND
|
|
|
classification_atc_id IS DISTINCT FROM (SELECT oid FROM eco.t_classification_atc WHERE code = 'Z99XX99');
|
|
|
|
|
|
UPDATE eco.t_articles SET
|
|
|
classification_atc_id = COALESCE(t_classification_atc.oid,0)
|
|
|
FROM prod_pharma.PRODUIT
|
|
|
JOIN eco.t_classification_atc ON CLASSETH = t_classification_atc.code_original AND length(CLASSETH) >= 7
|
|
|
WHERE
|
|
|
t_articles.code_original = PRCLEUNIK AND
|
|
|
(
|
|
|
classification_atc_id IS DISTINCT FROM COALESCE(t_classification_atc.oid,0)
|
|
|
);
|
|
|
|
|
|
|
|
|
UPDATE eco.t_articles SET
|
|
|
classification_atc_id = COALESCE(t_classification_atc.oid,0)
|
|
|
FROM prod_pharma.PRODUIT
|
|
|
JOIN eco.t_classification_atc ON CLASSETH || '99' = t_classification_atc.code_original AND length(CLASSETH) = 5
|
|
|
WHERE
|
|
|
substr(CLASSETH,2,1) BETWEEN '0' AND '9' AND
|
|
|
t_articles.code_original = PRCLEUNIK AND
|
|
|
(
|
|
|
classification_atc_id IS DISTINCT FROM COALESCE(t_classification_atc.oid,0)
|
|
|
);
|
|
|
|
|
|
UPDATE eco.t_articles SET
|
|
|
classification_atc_id = COALESCE(t_classification_atc.oid,0)
|
|
|
FROM prod_pharma.PRODUIT
|
|
|
JOIN eco.t_classification_atc ON CLASSETH || '99' = t_classification_atc.code_original AND length(CLASSETH) = 6
|
|
|
WHERE
|
|
|
substr(CLASSETH,2,1) NOT BETWEEN '0' AND '9' AND
|
|
|
t_articles.code_original = PRCLEUNIK AND
|
|
|
(
|
|
|
classification_atc_id IS DISTINCT FROM COALESCE(t_classification_atc.oid,0)
|
|
|
);
|
|
|
|
|
|
|
|
|
UPDATE eco.t_articles SET
|
|
|
classification_atc_id = COALESCE(t_classification_atc.oid,0)
|
|
|
FROM prod_pharma.PRODUIT
|
|
|
JOIN eco.t_classification_atc ON CLASSETH || 'X99' = t_classification_atc.code_original AND length(CLASSETH) = 4
|
|
|
WHERE
|
|
|
substr(CLASSETH,2,1) BETWEEN '0' AND '9' AND
|
|
|
t_articles.code_original = PRCLEUNIK AND
|
|
|
(
|
|
|
classification_atc_id IS DISTINCT FROM COALESCE(t_classification_atc.oid,0)
|
|
|
);
|
|
|
|
|
|
UPDATE eco.t_articles SET
|
|
|
classification_atc_id = COALESCE(t_classification_atc.oid,0)
|
|
|
FROM prod_pharma.PRODUIT
|
|
|
JOIN eco.t_classification_atc ON CLASSETH || 'X99' = t_classification_atc.code_original AND length(CLASSETH) = 5
|
|
|
WHERE
|
|
|
substr(CLASSETH,2,1) NOT BETWEEN '0' AND '9' AND
|
|
|
t_articles.code_original = PRCLEUNIK AND
|
|
|
(
|
|
|
classification_atc_id IS DISTINCT FROM COALESCE(t_classification_atc.oid,0)
|
|
|
);
|
|
|
|
|
|
|
|
|
UPDATE eco.t_articles SET
|
|
|
classification_atc_id = COALESCE(t_classification_atc.oid,0)
|
|
|
FROM prod_pharma.PRODUIT
|
|
|
JOIN eco.t_classification_atc ON CLASSETH || 'XX99' = t_classification_atc.code_original AND length(CLASSETH) = 3
|
|
|
WHERE
|
|
|
substr(CLASSETH,2,1) BETWEEN '0' AND '9' AND
|
|
|
t_articles.code_original = PRCLEUNIK AND
|
|
|
(
|
|
|
classification_atc_id IS DISTINCT FROM COALESCE(t_classification_atc.oid,0)
|
|
|
);
|
|
|
|
|
|
UPDATE eco.t_articles SET
|
|
|
classification_atc_id = COALESCE(t_classification_atc.oid,0)
|
|
|
FROM prod_pharma.PRODUIT
|
|
|
JOIN eco.t_classification_atc ON CLASSETH || 'XX99' = t_classification_atc.code_original AND length(CLASSETH) = 4
|
|
|
WHERE
|
|
|
substr(CLASSETH,2,1) NOT BETWEEN '0' AND '9' AND
|
|
|
t_articles.code_original = PRCLEUNIK AND
|
|
|
(
|
|
|
classification_atc_id IS DISTINCT FROM COALESCE(t_classification_atc.oid,0)
|
|
|
);
|
|
|
|
|
|
|
|
|
UPDATE eco.t_articles SET
|
|
|
classification_atc_id = COALESCE(t_classification_atc.oid,0)
|
|
|
FROM prod_pharma.PRODUIT
|
|
|
JOIN eco.t_classification_atc ON CLASSETH || '99XX99' = t_classification_atc.code_original AND length(CLASSETH) = 1
|
|
|
WHERE
|
|
|
substr(CLASSETH,2,1) BETWEEN '0' AND '9' AND
|
|
|
t_articles.code_original = PRCLEUNIK AND
|
|
|
(
|
|
|
classification_atc_id IS DISTINCT FROM COALESCE(t_classification_atc.oid,0)
|
|
|
);
|
|
|
|
|
|
UPDATE eco.t_articles SET
|
|
|
classification_atc_id = COALESCE(t_classification_atc.oid,0)
|
|
|
FROM prod_pharma.PRODUIT
|
|
|
JOIN eco.t_classification_atc ON CLASSETH || '99XX99' = t_classification_atc.code_original AND length(CLASSETH) = 2
|
|
|
WHERE
|
|
|
substr(CLASSETH,2,1) NOT BETWEEN '0' AND '9' AND
|
|
|
t_articles.code_original = PRCLEUNIK AND
|
|
|
(
|
|
|
classification_atc_id IS DISTINCT FROM COALESCE(t_classification_atc.oid,0)
|
|
|
);
|
|
|
|
|
|
|
|
|
UPDATE eco.t_articles SET
|
|
|
classification_atc_id = (SELECT oid FROM eco.t_classification_atc WHERE code = 'Z99XX99')
|
|
|
FROM prod_pharma.PRODUIT
|
|
|
LEFT JOIN eco.t_classification_atc ON CLASSETH = t_classification_atc.code_original
|
|
|
WHERE
|
|
|
t_articles.code_original = PRCLEUNIK AND
|
|
|
t_classification_atc.oid IS NULL AND
|
|
|
classification_atc_id IS DISTINCT FROM (SELECT oid FROM eco.t_classification_atc WHERE code = 'Z99XX99');
|
|
|
|
|
|
|
|
|
UPDATE eco.t_articles SET classification_atc_id = 0 WHERE classification_atc_id IS NULL;
|
|
|
|
|
|
UPDATE eco.t_articles SET
|
|
|
compte_id = COALESCE(t_compte.oid,0)
|
|
|
FROM prod_pharma.PRODUIT
|
|
|
LEFT JOIN eco.t_compte ON COMPTE = t_compte.code_original
|
|
|
WHERE
|
|
|
t_articles.code_original = PRCLEUNIK AND
|
|
|
(
|
|
|
compte_id IS DISTINCT FROM COALESCE(t_compte.oid,0)
|
|
|
);
|
|
|
|
|
|
UPDATE eco.t_articles SET compte_id = 0 WHERE compte_id IS NULL;
|
|
|
|
|
|
|
|
|
|
|
|
UPDATE eco.t_articles SET
|
|
|
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
|
|
|
);
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
-- Listes
|
|
|
|
|
|
INSERT INTO eco.t_listes(
|
|
|
code, texte, table_id, is_cti, show_omit, utilisateur_createur,
|
|
|
est_partagee_modification, chapitre)
|
|
|
SELECT subview.code, subview.texte, t_listes_tables.oid, '0', '0', 'administrateur', '0', ''
|
|
|
FROM eco.t_listes_tables
|
|
|
JOIN (
|
|
|
SELECT 'CTI_ART_GEST_1'::text AS code, 'Produits stockés'::text AS texte
|
|
|
UNION
|
|
|
SELECT 'CTI_ART_GEST_2'::text AS code, 'Produits non stockés'::text AS texte
|
|
|
UNION
|
|
|
SELECT 'CTI_ART_GEST_3'::text AS code, 'Produits en Dépot/Vente'::text AS texte
|
|
|
UNION
|
|
|
SELECT 'CTI_ART_GEST_4'::text AS code, 'Produits inactifs'::text AS texte
|
|
|
UNION
|
|
|
SELECT 'CTI_ART_LIVR_1'::text AS code, 'Sur livret'::text AS texte
|
|
|
UNION
|
|
|
SELECT 'CTI_ART_LIVR_2'::text AS code, 'Hors livret'::text AS texte
|
|
|
UNION
|
|
|
SELECT 'CTI_ART_LIVR_3'::text AS code, 'Attente livret'::text AS texte
|
|
|
UNION
|
|
|
SELECT 'CTI_ART_LIST_2'::text AS code, 'Liste I'::text AS texte
|
|
|
UNION
|
|
|
SELECT 'CTI_ART_LIST_3'::text AS code, 'Liste II'::text AS texte
|
|
|
UNION
|
|
|
SELECT 'CTI_ART_LIST_4'::text AS code, 'Stupéfiant'::text AS texte
|
|
|
|
|
|
) subview ON t_listes_tables.code = 'ART'
|
|
|
WHERE subview.code NOT IN (SELECT code FROM eco.t_listes);
|
|
|
|
|
|
|
|
|
DELETE FROM eco.t_listes_contenu
|
|
|
USING eco.t_listes
|
|
|
WHERE t_listes_contenu.liste_id = t_listes.oid AND t_listes.code LIKE 'CTI_ART_GEST%';
|
|
|
|
|
|
INSERT INTO eco.t_listes_contenu (liste_id, to_id)
|
|
|
SELECT
|
|
|
t_listes.oid, t_articles.oid
|
|
|
FROM eco.t_articles
|
|
|
JOIN prod_pharma.PRODUIT ON code_original = PRCLEUNIK
|
|
|
JOIN eco.t_listes ON t_listes.code = 'CTI_ART_GEST_' || MODEGEST
|
|
|
LEFT JOIN eco.t_listes_contenu ON t_listes.oid = liste_id AND t_articles.oid = to_id
|
|
|
WHERE liste_id IS NULL;
|
|
|
|
|
|
|
|
|
DELETE FROM eco.t_listes_contenu
|
|
|
USING eco.t_listes
|
|
|
WHERE t_listes_contenu.liste_id = t_listes.oid AND t_listes.code LIKE 'CTI_ART_LIVR%';
|
|
|
|
|
|
INSERT INTO eco.t_listes_contenu (liste_id, to_id)
|
|
|
SELECT
|
|
|
t_listes.oid, t_articles.oid
|
|
|
FROM eco.t_articles
|
|
|
JOIN prod_pharma.PRODUIT ON code_original = PRCLEUNIK
|
|
|
JOIN eco.t_listes ON t_listes.code = 'CTI_ART_LIVR_' || LIVRETPDT;
|
|
|
|
|
|
DELETE FROM eco.t_listes_contenu
|
|
|
USING eco.t_listes
|
|
|
WHERE t_listes_contenu.liste_id = t_listes.oid AND t_listes.code LIKE 'CTI_ART_LIST%';
|
|
|
|
|
|
INSERT INTO eco.t_listes_contenu (liste_id, to_id)
|
|
|
SELECT
|
|
|
t_listes.oid, t_articles.oid
|
|
|
FROM eco.t_articles
|
|
|
JOIN prod_pharma.PRODUIT ON code_original = PRCLEUNIK
|
|
|
JOIN eco.t_listes ON t_listes.code = 'CTI_ART_LIST_' || LISTEPR;
|
|
|
|
|
|
|
|
|
]]></sqlcmd>
|
|
|
</NODE>
|
|
|
|
|
|
|
|
|
<NODE label="Tables Fournisseurs">
|
|
|
<sqlcmd><![CDATA[
|
|
|
|
|
|
|
|
|
-- Fournisseurs
|
|
|
DROP TABLE IF EXISTS w_FOURNIS;
|
|
|
CREATE TEMP TABLE w_FOURNIS AS
|
|
|
SELECT
|
|
|
F0CLEUNIK AS code_original,
|
|
|
to_char(F0CLEUNIK,'FM00000') AS code,
|
|
|
FOURNIS.*
|
|
|
FROM prod_pharma.FOURNIS;
|
|
|
|
|
|
INSERT INTO base.t_codes_postaux(code, texte, texte_court, departement_id)
|
|
|
SELECT CPOSTFOUR, MAX(VILLEFOUR), MAX(VILLEFOUR), MAX(t_departements.oid)
|
|
|
FROM w_FOURNIS FOURNIS
|
|
|
LEFT JOIN base.t_codes_postaux ON CPOSTFOUR = t_codes_postaux.code
|
|
|
JOIN base.t_departements ON CASE WHEN length(CPOSTFOUR) = 5 THEN substr(CPOSTFOUR,1,2) else '99' END = t_departements.code
|
|
|
WHERE t_codes_postaux.oid IS NULL AND
|
|
|
CPOSTFOUR <> '' AND
|
|
|
CPOSTFOUR <> '0'
|
|
|
GROUP BY 1
|
|
|
;
|
|
|
|
|
|
INSERT INTO eco.t_fournisseurs(code, texte, texte_court, code_original)
|
|
|
SELECT w_FOURNIS.code, w_FOURNIS.FOURNIS, w_FOURNIS.FOURNIS, w_FOURNIS.code_original
|
|
|
FROM w_FOURNIS
|
|
|
LEFT JOIN eco.t_fournisseurs ON (w_FOURNIS.code_original = t_fournisseurs.code_original)
|
|
|
WHERE t_fournisseurs.code_original IS NULL;
|
|
|
|
|
|
|
|
|
UPDATE eco.t_fournisseurs
|
|
|
SET code = w_FOURNIS.code,
|
|
|
texte = w_FOURNIS.FOURNIS,
|
|
|
texte_court = w_FOURNIS.FOURNIS,
|
|
|
adresse = trim(ADRFOUR1 || ' ' || ADRFOUR2),
|
|
|
code_postal_id = COALESCE(t_codes_postaux.oid,0),
|
|
|
ville = VILLEFOUR,
|
|
|
telephone = TELFOUR,
|
|
|
fax = FAXFOUR,
|
|
|
email = MAILCONTACTFO,
|
|
|
siret = W_FOURNIS.SIRET
|
|
|
FROM w_FOURNIS
|
|
|
LEFT JOIN base.t_codes_postaux ON CPOSTFOUR = t_codes_postaux.code
|
|
|
WHERE w_FOURNIS.code_original = t_fournisseurs.code_original
|
|
|
AND (
|
|
|
t_fournisseurs.code IS DISTINCT FROM w_FOURNIS.code OR
|
|
|
t_fournisseurs.texte IS DISTINCT FROM w_FOURNIS.FOURNIS OR
|
|
|
t_fournisseurs.texte_court IS DISTINCT FROM w_FOURNIS.FOURNIS OR
|
|
|
adresse IS DISTINCT FROM trim(ADRFOUR1 || ' ' || ADRFOUR2) OR
|
|
|
code_postal_id IS DISTINCT FROM COALESCE(t_codes_postaux.oid,0) OR
|
|
|
ville IS DISTINCT FROM VILLEFOUR OR
|
|
|
telephone IS DISTINCT FROM TELFOUR OR
|
|
|
fax IS DISTINCT FROM FAXFOUR OR
|
|
|
email IS DISTINCT FROM MAILCONTACTFO OR
|
|
|
t_fournisseurs.siret IS DISTINCT FROM W_FOURNIS.SIRET
|
|
|
)
|
|
|
;
|
|
|
|
|
|
|
|
|
UPDATE eco.t_fournisseurs SET
|
|
|
type_id = 0
|
|
|
WHERE type_id IS NULL;
|
|
|
|
|
|
|
|
|
UPDATE eco.t_fournisseurs SET
|
|
|
type_code = t_types_fournisseurs.code,
|
|
|
type_texte = t_types_fournisseurs.texte_court,
|
|
|
type_section_id = t_types_fournisseurs.section_id,
|
|
|
type_section_code = t_types_fournisseurs.section_code,
|
|
|
type_section_texte = t_types_fournisseurs.section_texte
|
|
|
FROM eco.t_types_fournisseurs
|
|
|
WHERE type_id = t_types_fournisseurs.oid
|
|
|
AND (
|
|
|
type_code IS DISTINCT FROM t_types_fournisseurs.code OR
|
|
|
type_texte IS DISTINCT FROM t_types_fournisseurs.texte_court OR
|
|
|
type_section_id IS DISTINCT FROM t_types_fournisseurs.section_id OR
|
|
|
type_section_code IS DISTINCT FROM t_types_fournisseurs.section_code OR
|
|
|
type_section_texte IS DISTINCT FROM t_types_fournisseurs.section_texte
|
|
|
);
|
|
|
|
|
|
|
|
|
|
|
|
-- Articles fournisseurs
|
|
|
DROP TABLE IF EXISTS w_article_fournisseur;
|
|
|
CREATE TEMP TABLE w_article_fournisseur AS
|
|
|
SELECT F2CLEUNIK::text AS code_original,
|
|
|
FOURPRO.F0CLEUNIK,
|
|
|
FOURPRO.PRCLEUNIK,
|
|
|
COALESCE(t_articles.oid,0) AS article_id,
|
|
|
COALESCE(t_fournisseurs.oid,0) AS fournisseur_id,
|
|
|
CASE WHEN FOURPRO.F0CLEUNIK = PRODUIT.PRCLEUNIK THEN '1' ELSE '0' END AS est_fournisseur_principal,
|
|
|
COALESCE(t_fournisseurs.oid,0) AS fournisseur_distributeur_id,
|
|
|
CASE WHEN LIBCALCPR <> '' THEN LIBCALCPR ELSE PRNOM END AS texte_reference_fournisseur,
|
|
|
''::text AS code_cahpp,
|
|
|
CASE
|
|
|
WHEN FOURPRO.REFFOURPR LIKE '34009%' AND length(FOURPRO.REFFOURPR) = 13 THEN FOURPRO.REFFOURPR
|
|
|
WHEN PRODUIT.REFFOURPR LIKE '34009%' AND length(PRODUIT.REFFOURPR) = 13 THEN PRODUIT.REFFOURPR
|
|
|
ELSE '' END AS code_cip,
|
|
|
FOURPRO.REFFOURPR AS code_reference_fournisseur,
|
|
|
PRODUIT.UCD13 AS code_ucd13,
|
|
|
PRODUIT.UCD7 AS code_ucd,
|
|
|
0::bigint AS ucd_id,
|
|
|
SUBVIEW.CODELPP AS code_lpp,
|
|
|
0::bigint AS lpp_id,
|
|
|
0::bigint AS unite_approvisionnement_id,
|
|
|
FOURPRO.CDTACHAT AS nombre_conditionnement_approvisionnement,
|
|
|
CASE WHEN base.cti_to_number(FOURPRO.PRIXMARCHE) <> 0 THEN base.cti_to_number(FOURPRO.PRIXMARCHE) ELSE FOURPRO.PRIXTARIF END AS prix_unitaire_en_cours
|
|
|
FROM prod_pharma.FOURPRO
|
|
|
JOIN
|
|
|
(
|
|
|
SELECT PRCLEUNIK, F0CLEUNIK, (MAX(ARRAY[FINMARPR::text, F2CLEUNIK::text]))[2]::bigint AS F2CLEUNIK_keep
|
|
|
FROM prod_pharma.FOURPRO
|
|
|
GROUP BY 1,2
|
|
|
) subview_FOURPRO ON
|
|
|
FOURPRO.PRCLEUNIK = subview_FOURPRO.PRCLEUNIK AND
|
|
|
FOURPRO.F0CLEUNIK = subview_FOURPRO.F0CLEUNIK AND
|
|
|
FOURPRO.F2CLEUNIK = subview_FOURPRO.F2CLEUNIK_keep
|
|
|
JOIN prod_pharma.PRODUIT ON FOURPRO.PRCLEUNIK = PRODUIT.PRCLEUNIK
|
|
|
JOIN eco.t_articles ON FOURPRO.PRCLEUNIK = t_articles.code_original
|
|
|
JOIN eco.t_fournisseurs ON FOURPRO.F0CLEUNIK = t_fournisseurs.code_original
|
|
|
LEFT JOIN
|
|
|
(
|
|
|
SELECT
|
|
|
PRCLEUNIK,
|
|
|
(MAX(ARRAY[PRINC::text,CODELPP]))[2]::text AS CODELPP
|
|
|
FROM prod_pharma.PRODUITLPP
|
|
|
GROUP BY 1
|
|
|
) subview ON FOURPRO.PRCLEUNIK = subview.PRCLEUNIK
|
|
|
;
|
|
|
|
|
|
ANALYSE w_article_fournisseur
|
|
|
;
|
|
|
|
|
|
|
|
|
UPDATE w_article_fournisseur
|
|
|
SET lpp_id = t_lpp.oid
|
|
|
FROM base.t_lpp
|
|
|
WHERE code_lpp <> '' AND
|
|
|
code_lpp = t_lpp.code
|
|
|
;
|
|
|
|
|
|
UPDATE w_article_fournisseur
|
|
|
SET code_ucd13 = subview.code_ucd, code_ucd = substr(subview.code_ucd,6,7)
|
|
|
FROM
|
|
|
(
|
|
|
SELECT PRCLEUNIK, F0CLEUNIK, (MAX(ARRAY[DATEMVT::text,CODE_UCD::text]))[2] AS code_ucd
|
|
|
FROM w_MVTPDT
|
|
|
WHERE length(CODE_UCD::text) = 13 AND CODE_UCD LIKE '34008%'
|
|
|
GROUP BY 1,2
|
|
|
) subview
|
|
|
WHERE w_article_fournisseur.PRCLEUNIK = subview.PRCLEUNIK AND
|
|
|
w_article_fournisseur.F0CLEUNIK = subview.F0CLEUNIK AND
|
|
|
w_article_fournisseur.code_ucd13 = ''
|
|
|
;
|
|
|
|
|
|
UPDATE w_article_fournisseur
|
|
|
SET code_ucd13 = subview.code_ucd, code_ucd = substr(subview.code_ucd,6,7)
|
|
|
FROM
|
|
|
(
|
|
|
SELECT PRCLEUNIK, (MAX(ARRAY[DATEMVT::text,CODE_UCD::text]))[2] AS code_ucd
|
|
|
FROM w_MVTPDT
|
|
|
WHERE length(CODE_UCD::text) = 13 AND CODE_UCD LIKE '34008%'
|
|
|
GROUP BY 1
|
|
|
) subview
|
|
|
WHERE w_article_fournisseur.PRCLEUNIK = subview.PRCLEUNIK AND
|
|
|
w_article_fournisseur.code_ucd13 = ''
|
|
|
;
|
|
|
|
|
|
UPDATE w_article_fournisseur
|
|
|
SET code_ucd = subview.code_ucd
|
|
|
FROM
|
|
|
(
|
|
|
SELECT PRCLEUNIK, F0CLEUNIK, (MAX(ARRAY[DATEMVT::text,CODE_UCD::text]))[2] AS code_ucd
|
|
|
FROM w_MVTPDT
|
|
|
WHERE length(CODE_UCD::text) = 7 AND CODE_UCD::text LIKE '9%'
|
|
|
GROUP BY 1,2
|
|
|
) subview
|
|
|
WHERE w_article_fournisseur.PRCLEUNIK = subview.PRCLEUNIK AND
|
|
|
w_article_fournisseur.F0CLEUNIK = subview.F0CLEUNIK AND
|
|
|
w_article_fournisseur.code_ucd = ''
|
|
|
;
|
|
|
|
|
|
UPDATE w_article_fournisseur
|
|
|
SET code_ucd = subview.code_ucd
|
|
|
FROM
|
|
|
(
|
|
|
SELECT PRCLEUNIK,(MAX(ARRAY[DATEMVT::text,CODE_UCD::text]))[2] AS code_ucd
|
|
|
FROM w_MVTPDT
|
|
|
WHERE length(CODE_UCD::text) = 7 AND CODE_UCD::text LIKE '9%'
|
|
|
GROUP BY 1
|
|
|
) subview
|
|
|
WHERE w_article_fournisseur.PRCLEUNIK = subview.PRCLEUNIK AND
|
|
|
w_article_fournisseur.code_ucd = ''
|
|
|
;
|
|
|
|
|
|
UPDATE w_article_fournisseur
|
|
|
SET ucd_id = t_ucd.oid
|
|
|
FROM base.t_ucd
|
|
|
WHERE code_ucd <> '' AND
|
|
|
code_ucd = t_ucd.code
|
|
|
;
|
|
|
|
|
|
|
|
|
|
|
|
DELETE FROM eco.t_article_fournisseur
|
|
|
WHERE code_original NOT IN (SELECT w_article_fournisseur.code_original FROM w_article_fournisseur)
|
|
|
;
|
|
|
|
|
|
|
|
|
INSERT INTO eco.t_article_fournisseur (
|
|
|
code_original,
|
|
|
article_id,
|
|
|
fournisseur_id,
|
|
|
est_fournisseur_principal,
|
|
|
fournisseur_distributeur_id,
|
|
|
texte_reference_fournisseur,
|
|
|
code_cahpp,
|
|
|
code_cip,
|
|
|
code_reference_fournisseur,
|
|
|
code_ucd13,
|
|
|
ucd_id,
|
|
|
lpp_id,
|
|
|
unite_approvisionnement_id,
|
|
|
nombre_conditionnement_approvisionnement,
|
|
|
prix_unitaire_en_cours
|
|
|
)
|
|
|
SELECT
|
|
|
code_original,
|
|
|
article_id,
|
|
|
fournisseur_id,
|
|
|
est_fournisseur_principal,
|
|
|
fournisseur_distributeur_id,
|
|
|
texte_reference_fournisseur,
|
|
|
code_cahpp,
|
|
|
code_cip,
|
|
|
code_reference_fournisseur,
|
|
|
code_ucd13,
|
|
|
ucd_id,
|
|
|
lpp_id,
|
|
|
unite_approvisionnement_id,
|
|
|
nombre_conditionnement_approvisionnement,
|
|
|
prix_unitaire_en_cours
|
|
|
FROM w_article_fournisseur
|
|
|
WHERE code_original NOT IN (SELECT t_article_fournisseur.code_original FROM eco.t_article_fournisseur)
|
|
|
;
|
|
|
|
|
|
UPDATE eco.t_article_fournisseur SET
|
|
|
article_id = w_article_fournisseur.article_id,
|
|
|
fournisseur_id = w_article_fournisseur.fournisseur_id,
|
|
|
est_fournisseur_principal = w_article_fournisseur.est_fournisseur_principal,
|
|
|
fournisseur_distributeur_id = w_article_fournisseur.fournisseur_distributeur_id,
|
|
|
texte_reference_fournisseur = w_article_fournisseur.texte_reference_fournisseur,
|
|
|
code_cahpp = w_article_fournisseur.code_cahpp,
|
|
|
code_cip = w_article_fournisseur.code_cip,
|
|
|
code_reference_fournisseur = w_article_fournisseur.code_reference_fournisseur,
|
|
|
code_ucd13 = w_article_fournisseur.code_ucd13,
|
|
|
ucd_id = w_article_fournisseur.ucd_id,
|
|
|
lpp_id = w_article_fournisseur.lpp_id,
|
|
|
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
|
|
|
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.est_fournisseur_principal IS DISTINCT FROM w_article_fournisseur.est_fournisseur_principal OR
|
|
|
t_article_fournisseur.fournisseur_distributeur_id IS DISTINCT FROM w_article_fournisseur.fournisseur_distributeur_id OR
|
|
|
t_article_fournisseur.texte_reference_fournisseur IS DISTINCT FROM w_article_fournisseur.texte_reference_fournisseur OR
|
|
|
t_article_fournisseur.code_cahpp IS DISTINCT FROM w_article_fournisseur.code_cahpp OR
|
|
|
t_article_fournisseur.code_cip IS DISTINCT FROM w_article_fournisseur.code_cip OR
|
|
|
t_article_fournisseur.code_reference_fournisseur IS DISTINCT FROM w_article_fournisseur.code_reference_fournisseur OR
|
|
|
t_article_fournisseur.code_ucd13 IS DISTINCT FROM w_article_fournisseur.code_ucd13 OR
|
|
|
t_article_fournisseur.ucd_id IS DISTINCT FROM w_article_fournisseur.ucd_id OR
|
|
|
t_article_fournisseur.lpp_id IS DISTINCT FROM w_article_fournisseur.lpp_id 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
|
|
|
)
|
|
|
;
|
|
|
|
|
|
|
|
|
]]></sqlcmd>
|
|
|
</NODE>
|
|
|
|
|
|
|
|
|
|
|
|
<NODE label="Autres tables">
|
|
|
<sqlcmd><![CDATA[
|
|
|
|
|
|
|
|
|
-- Unités fonctionnelles
|
|
|
|
|
|
INSERT INTO eco.t_unites_fonctionnelles(code, texte, texte_court, code_original)
|
|
|
SELECT SERVICE, NOMSERVICE, substr(NOMSERVICE,1,50), SERVICE
|
|
|
FROM prod_pharma.SERVICE
|
|
|
LEFT JOIN eco.t_unites_fonctionnelles ON (code_original = SERVICE)
|
|
|
WHERE code_original IS NULL AND
|
|
|
SERVICE <> '' AND SERVICE <> '-1';
|
|
|
|
|
|
INSERT INTO eco.t_unites_fonctionnelles(code, texte, texte_court, code_original)
|
|
|
SELECT SERVICE, SERVICE, SERVICE, SERVICE
|
|
|
FROM w_MVTPDT
|
|
|
LEFT JOIN eco.t_unites_fonctionnelles ON t_unites_fonctionnelles.code_original = w_MVTPDT.SERVICE
|
|
|
WHERE t_unites_fonctionnelles.code_original IS NULL AND
|
|
|
SERVICE <> '' AND
|
|
|
SERVICE <> '-1'
|
|
|
GROUP BY 1
|
|
|
;
|
|
|
|
|
|
UPDATE eco.t_unites_fonctionnelles
|
|
|
SET texte = NOMSERVICE,
|
|
|
texte_court = substr(NOMSERVICE,1,50)
|
|
|
FROM prod_pharma.SERVICE
|
|
|
WHERE code_original = SERVICE
|
|
|
AND (texte IS DISTINCT FROM NOMSERVICE OR
|
|
|
texte_court IS DISTINCT FROM substr(NOMSERVICE,1,50));
|
|
|
|
|
|
|
|
|
-- Types mouvements
|
|
|
|
|
|
|
|
|
INSERT INTO eco.t_types_mouvements(code_original, code, texte, texte_court )
|
|
|
SELECT
|
|
|
to_char(TYPEMVT,'FM00') || '|' || TYPESORTIE,
|
|
|
to_char(TYPEMVT,'FM00') || CASE WHEN TYPESORTIE <> '' THEN '_' || TYPESORTIE ELSE '' END,
|
|
|
to_char(TYPEMVT,'FM00') || CASE WHEN TYPESORTIE <> '' THEN '_' || TYPESORTIE ELSE '' END,
|
|
|
to_char(TYPEMVT,'FM00') || CASE WHEN TYPESORTIE <> '' THEN '_' || TYPESORTIE ELSE '' END
|
|
|
FROM
|
|
|
(SELECT TYPEMVT, TYPESORTIE
|
|
|
FROM w_MVTPDT
|
|
|
WHERE DATEMVT BETWEEN '[ENV_ECO_ANNEEDEBUT]0101' AND now()
|
|
|
GROUP BY 1,2) subview
|
|
|
LEFT JOIN eco.t_types_mouvements ON code_original = to_char(TYPEMVT,'FM00') || '|' || TYPESORTIE
|
|
|
WHERE code_original IS NULL
|
|
|
GROUP BY 1,2
|
|
|
ORDER BY 1;
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
-- Profils
|
|
|
|
|
|
INSERT INTO eco.t_profils_comptables
|
|
|
(
|
|
|
oid,
|
|
|
code_original,
|
|
|
centre_responsabilite_id,
|
|
|
unite_fonctionnelle_id)
|
|
|
SELECT
|
|
|
0 AS oid,
|
|
|
'0' AS code_original,
|
|
|
0 AS centre_responsabilite_id,
|
|
|
0 AS unite_fonctionnelle_id
|
|
|
WHERE 0 NOT IN (SELECT oid FROM eco.t_profils_comptables);
|
|
|
|
|
|
]]></sqlcmd>
|
|
|
</NODE>
|
|
|
|
|
|
|
|
|
</NODE>
|
|
|
<NODE name="PROD" label="RECUPERATION DES DONNEES DE PRODUCTION">
|
|
|
<NODE label="Commandes">
|
|
|
<sqlcmd><![CDATA[
|
|
|
|
|
|
TRUNCATE eco.p_commandes;
|
|
|
|
|
|
INSERT INTO eco.p_commandes(
|
|
|
code_original,
|
|
|
numero,
|
|
|
date_commande,
|
|
|
objet,
|
|
|
reference,
|
|
|
date_livraison_prevue,
|
|
|
etat_reception,
|
|
|
date_reception,
|
|
|
etat_liquidation,
|
|
|
fournisseur_id,
|
|
|
fournisseur_distributeur_id,
|
|
|
gestionnaire_id,
|
|
|
lieu_commande_id,
|
|
|
lieu_facturation_id,
|
|
|
lieu_livraison_id,
|
|
|
site_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
|
|
|
C1CLEUNIK,
|
|
|
to_char(NUMCMDE,'FM0000000') || SUFCMDE AS numero,
|
|
|
date(DATECMDE) AS date_commande,
|
|
|
trim(C_EDI_NUMCOMMANDE) || CASE WHEN COMMENTCDE != '' THEN ' - ' ELSE ''END || C_EDI_NUMCOMMANDE AS objet,
|
|
|
trim(REFFACT) AS reference,
|
|
|
date(DATELIVS) AS date_livraison_prevue,
|
|
|
CASE WHEN DATELIVCMD IS NOT NULL THEN 'T' ELSE 'N' END AS etat_reception,
|
|
|
date(DATELIVCMD) AS date_reception,
|
|
|
CASE WHEN NOLIQUID IS NOT NULL THEN 'T' ELSE 'N' END AS etat_liquidation,
|
|
|
COALESCE(t_fournisseurs.oid,0) AS fournisseur_id,
|
|
|
COALESCE(t_fournisseurs.oid,0) AS fournisseur_distributeur_id,
|
|
|
COALESCE(t_gestionnaires.oid,0) AS gestionnaire_id,
|
|
|
COALESCE(t_lieux_commande.oid,0) AS lieu_commande_id,
|
|
|
COALESCE(t_lieux_facturation.oid,0) AS lieu_facturation_id,
|
|
|
COALESCE(t_lieux_livraison.oid,0) AS lieu_livraison_id,
|
|
|
COALESCE(t_sites.oid,0) AS site_id,
|
|
|
COALESCE(t_unites_fonctionnelles.oid,0)AS unite_fonctionnelle_id,
|
|
|
CASE WHEN TOTFACTHT <> 0 THEN TOTFACTHT ELSE TOTCMDEHT END AS montant_commande_ht,
|
|
|
0 AS montant_commande_remise,
|
|
|
CASE WHEN TOTFACTHT <> 0 THEN TOTALTVA ELSE TOTCMDETTC - TOTFACTHT END AS montant_commande_tva,
|
|
|
PORTTTC AS montant_commande_port,
|
|
|
CASE WHEN TOTFACTHT <> 0 THEN TOTFACTTTC ELSE 0 END AS montant_commande_total,
|
|
|
CASE WHEN NOLIQUID IS NOT NULL THEN TOTFACTHT ELSE 0 END AS montant_liquidation_ht,
|
|
|
0 AS montant_liquidation_remise,
|
|
|
CASE WHEN NOLIQUID IS NOT NULL THEN TOTALTVA ELSE 0 END AS montant_liquidation_tva,
|
|
|
CASE WHEN NOLIQUID IS NOT NULL THEN PORTTTC ELSE 0 END AS montant_liquidation_port,
|
|
|
CASE WHEN NOLIQUID IS NOT NULL THEN TOTFACTTTC ELSE 0 END AS montant_liquidation_total
|
|
|
FROM w_COMMANDE
|
|
|
LEFT JOIN eco.t_fournisseurs ON F0CLEUNIK = t_fournisseurs.code_original
|
|
|
LEFT JOIN eco.t_gestionnaires ON '0' = t_gestionnaires.code_original
|
|
|
LEFT JOIN eco.t_divers ON t_divers.code = 'PHARMA_MAG_LIEU'
|
|
|
LEFT JOIN eco.t_lieux t_lieux_commande ON CASE WHEN t_divers.valeur = '1' THEN COALESCE(MAGASIN::text,'0') ELSE '0' END = t_lieux_commande.code_original
|
|
|
LEFT JOIN eco.t_lieux t_lieux_facturation ON CASE WHEN t_divers.valeur = '1' THEN COALESCE(MAGASIN::text,'0') ELSE '0' END = t_lieux_facturation.code_original
|
|
|
LEFT JOIN eco.t_lieux t_lieux_livraison ON CASE WHEN t_divers.valeur = '1' THEN COALESCE(MAGASIN::text,'0') ELSE '0' END = t_lieux_livraison.code_original
|
|
|
LEFT JOIN eco.t_sites ON MAGASIN = t_sites.code
|
|
|
LEFT JOIN eco.t_unites_fonctionnelles ON '0' = t_unites_fonctionnelles.code_original
|
|
|
;
|
|
|
|
|
|
DROP TABLE IF EXISTS w_ligne;
|
|
|
CREATE TEMP TABLE w_ligne AS
|
|
|
SELECT
|
|
|
C1CLEUNIK,
|
|
|
L0CLEUNIK,
|
|
|
PRCLEUNIK,
|
|
|
NOLIGCMDE,
|
|
|
TXTCMDEDET,
|
|
|
QTELIV,
|
|
|
QTECMDE,
|
|
|
PRIXCMDE,
|
|
|
FACTHT,
|
|
|
VALEURHT,
|
|
|
LGREMISEVALTTC,
|
|
|
TOTALTVA,
|
|
|
VALEURTVA,
|
|
|
FACTTTC,
|
|
|
VALEURTTC,
|
|
|
TVA,
|
|
|
NONLIQUIDE
|
|
|
FROM w_LIGNE_source LIGNE
|
|
|
GROUP BY 1,2,3,4,5,6,7,8,9,10,11,12,13,14,15,16,17
|
|
|
;
|
|
|
|
|
|
TRUNCATE eco.p_lignes_commandes;
|
|
|
|
|
|
INSERT INTO eco.t_divers (code, texte, valeur, description)
|
|
|
SELECT
|
|
|
'PHARMA_COM_LIGNE_NLIV',
|
|
|
'Remontée des lignes non livrées des commandes soldées',
|
|
|
'0',
|
|
|
'0=Ne pas les remonter 1=Les remonter'
|
|
|
WHERE 'PHARMA_COM_LIGNE_NLIV' NOT IN (SELECT code FROM eco.t_divers);
|
|
|
|
|
|
INSERT INTO eco.p_lignes_commandes(
|
|
|
code_original,
|
|
|
commande_id,
|
|
|
ligne_commande,
|
|
|
texte,
|
|
|
article_id,
|
|
|
fournisseur_distributeur_id,
|
|
|
unite_approvisionnement_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_ttc,
|
|
|
etat_livraison,
|
|
|
|
|
|
montant_liquidation_ht,
|
|
|
montant_liquidation_remise,
|
|
|
montant_liquidation_tva,
|
|
|
montant_liquidation_port,
|
|
|
montant_liquidation_ttc,
|
|
|
etat_liquidation,
|
|
|
taux_prorata_tva,
|
|
|
taux_tva)
|
|
|
SELECT
|
|
|
L0CLEUNIK AS code_original,
|
|
|
p_commandes.oid AS commande_id,
|
|
|
NOLIGCMDE AS ligne_commande,
|
|
|
substr(TXTCMDEDET,1,255) AS texte,
|
|
|
t_articles.oid AS article_id,
|
|
|
p_commandes.fournisseur_distributeur_id,
|
|
|
COALESCE(t_unites.oid,t_articles.unite_stockage_id) AS unite_approvisionnement_id,
|
|
|
t_articles.compte_id AS compte_id,
|
|
|
(CASE WHEN ETATCMDE IN ('4') AND COALESCE(t_divers.valeur,'0') = '0' THEN QTELIV ELSE QTECMDE END)::numeric AS quantite_approvisionnement,
|
|
|
PRIXCMDE AS prix_unitaire_approvisionnement,
|
|
|
1 AS multiplicateur_stockage,
|
|
|
QTECMDE::numeric AS quantite_stockage,
|
|
|
PRIXCMDE::numeric AS prix_unitaire_stockage,
|
|
|
|
|
|
CASE WHEN FACTHT <> 0 THEN FACTHT ELSE PRIXCMDE::numeric*QTECMDE::numeric END AS montant_commande_ht,
|
|
|
CASE WHEN FACTHT <> 0 THEN 0 - LGREMISEVALTTC ELSE 0 END AS montant_commande_remise,
|
|
|
CASE WHEN FACTHT <> 0 THEN w_LIGNE.TOTALTVA ELSE VALEURTVA END AS montant_commande_tva,
|
|
|
0 AS montant_commande_port,
|
|
|
CASE WHEN FACTHT <> 0 THEN FACTTTC ELSE VALEURTTC END AS montant_commande_ttc,
|
|
|
|
|
|
QTELIV::numeric AS quantite_livraison_approvisionnement,
|
|
|
QTELIV::numeric AS quantite_livraison_stockage,
|
|
|
CASE WHEN FACTHT <> 0 THEN FACTHT ELSE CASE WHEN QTELIV = 0 THEN 0 ELSE VALEURHT::numeric END END AS montant_livraison_ht,
|
|
|
CASE WHEN FACTTTC <> 0 THEN FACTTTC ELSE CASE WHEN QTELIV = 0 THEN 0 ELSE VALEURTTC::numeric END END AS montant_livraison_ttc,
|
|
|
CASE WHEN (ETATCMDE IN ('4') AND COALESCE(t_divers.valeur,'0') = '0') OR QTELIV = QTECMDE THEN 'T' WHEN QTELIV = QTECMDE THEN 'S' WHEN QTELIV = 0 THEN 'N' ELSE 'P' END AS etat_livraison,
|
|
|
|
|
|
CASE WHEN NONLIQUIDE <> '1' THEN FACTHT ELSE 0 END AS montant_liquidation_ht,
|
|
|
CASE WHEN NONLIQUIDE <> '1' THEN 0 ELSE 0 END AS montant_liquidation_remise,
|
|
|
CASE WHEN NONLIQUIDE <> '1' THEN w_LIGNE.TOTALTVA ELSE 0 END AS montant_liquidation_tva,
|
|
|
CASE WHEN NONLIQUIDE <> '1' THEN 0 ELSE 0 END AS montant_liquidation_port,
|
|
|
CASE WHEN NONLIQUIDE <> '1' THEN FACTTTC ELSE 0 END AS montant_liquidation_ttc,
|
|
|
CASE WHEN NONLIQUIDE <> '1' THEN 'T' ELSE 'N' END AS etat_liquidation,
|
|
|
|
|
|
CASE WHEN t_articles.type_prorata_tva IS DISTINCT FROM '1' THEN COALESCE(t_prorata_tva.taux,0) ELSE 0 END,
|
|
|
round(COALESCE(VALPARAMRE,0)::numeric,1)
|
|
|
|
|
|
FROM w_LIGNE
|
|
|
LEFT JOIN prod_pharma.PARAMETR ON CODEPARAM = 'RTVA'||w_LIGNE.TVA
|
|
|
JOIN w_COMMANDE ON w_COMMANDE.C1CLEUNIK = w_LIGNE.C1CLEUNIK
|
|
|
JOIN eco.p_commandes ON w_LIGNE.C1CLEUNIK = p_commandes.code_original
|
|
|
JOIN eco.t_articles ON PRCLEUNIK = t_articles.code_original
|
|
|
LEFT JOIN eco.t_unites ON '0' = t_unites.code_original
|
|
|
LEFT JOIN eco.t_prorata_tva ON t_prorata_tva.oid = 0
|
|
|
LEFT JOIN eco.t_divers ON t_divers.code = 'PHARMA_COM_LIGNE_NLIV'
|
|
|
WHERE ETATCMDE <> '4' OR CASE WHEN COALESCE(t_divers.valeur,'0') = '0' THEN QTELIV <> 0 ELSE QTECMDE <> 0 END;
|
|
|
|
|
|
ANALYSE eco.p_lignes_commandes;
|
|
|
|
|
|
|
|
|
UPDATE eco.p_lignes_commandes SET
|
|
|
montant_commande_tva = sub.taux_tva * p_lignes_commandes.montant_commande_ht,
|
|
|
montant_commande_ttc = (1 + sub.taux_tva) * p_lignes_commandes.montant_commande_ht
|
|
|
FROM
|
|
|
(SELECT
|
|
|
article_id,
|
|
|
p_commandes.date_reception,
|
|
|
COALESCE(lead(p_commandes.date_reception) OVER (PARTITION BY article_id ORDER BY p_commandes.date_reception),'2099-12-31') as date_reception_next,
|
|
|
COALESCE(lag(p_commandes.date_reception) OVER (PARTITION BY article_id ORDER BY p_commandes.date_reception),'1900-01-01') as date_reception_prev,
|
|
|
p_lignes_commandes.montant_commande_ttc/p_lignes_commandes.montant_commande_ht -1 AS taux_tva
|
|
|
FROM eco.p_commandes
|
|
|
JOIN eco.p_lignes_commandes ON commande_id = p_commandes.oid
|
|
|
WHERE p_lignes_commandes.montant_commande_ht != 0
|
|
|
AND p_lignes_commandes.montant_commande_ttc != 0
|
|
|
AND p_commandes.date_reception is not null
|
|
|
) sub,
|
|
|
eco.p_commandes
|
|
|
WHERE p_commandes.oid = commande_id
|
|
|
AND p_lignes_commandes.montant_commande_ht != 0 AND p_lignes_commandes.montant_commande_ttc = 0
|
|
|
AND p_lignes_commandes.article_id = sub.article_id
|
|
|
AND (date_commande BETWEEN sub.date_reception AND date_reception_next OR
|
|
|
(date_commande BETWEEN date_reception_prev AND sub.date_reception AND date_reception_prev = '1900-01-01'))
|
|
|
;
|
|
|
|
|
|
]]></sqlcmd>
|
|
|
</NODE>
|
|
|
|
|
|
<NODE label="Stocks">
|
|
|
<sqlcmd><![CDATA[
|
|
|
|
|
|
DROP TABLE IF EXISTS w_stocks;
|
|
|
CREATE TEMP TABLE w_stocks AS
|
|
|
SELECT
|
|
|
t_articles.oid AS article_id,
|
|
|
date(date_trunc('month',DATEMVT) + interval '1 month' - interval '1 day') AS date_fin,
|
|
|
date(date_trunc('month',DATEMVT)) AS date_debut,
|
|
|
date_part('year',DATEMVT) * 12 + date_part('month',DATEMVT) AS mois_sequence,
|
|
|
MODEGEST,
|
|
|
MAGASIN,
|
|
|
0::bigint AS ucd_id,
|
|
|
0::bigint AS lpp_id,
|
|
|
COALESCE(t_articles.compte_id,0) AS compte_id,
|
|
|
|
|
|
COALESCE(t_sites.oid,0) AS site_id,
|
|
|
COALESCE(t_lieux.oid,0) AS lieu_id,
|
|
|
|
|
|
0::bigint AS provider_id,
|
|
|
t_articles.fournisseur_principal_id AS fournisseur_id,
|
|
|
0.00 AS stock_quantite_debut,
|
|
|
0.00 AS stock_valeur_debut,
|
|
|
0.00 AS stock_valeur_debut_ttc,
|
|
|
SUM(QUANTITE::numeric * (CASE WHEN SENSMVT = 1 THEN 1 ELSE 0 END)) AS entree_quantite,
|
|
|
SUM(VALHT::numeric * (CASE WHEN SENSMVT = 1 THEN 1 ELSE 0 END)) AS entree_montant,
|
|
|
SUM(VALTTC::numeric * (CASE WHEN SENSMVT = 1 THEN 1 ELSE 0 END)) AS entree_montant_ttc,
|
|
|
SUM(CASE WHEN SENSMVT = 1 AND TYPEMVT NOT IN (4,5) THEN QUANTITE::numeric ELSE 0 END) AS entree_quantite_pump,
|
|
|
SUM(CASE WHEN SENSMVT = 1 AND TYPEMVT NOT IN (4,5) THEN VALHT::numeric ELSE 0 END) AS entree_montant_pump,
|
|
|
SUM(CASE WHEN SENSMVT = 1 AND TYPEMVT NOT IN (4,5) THEN VALTTC::numeric ELSE 0 END) AS entree_montant_pump_ttc,
|
|
|
0.00 AS pump,
|
|
|
0.00 AS pump_ttc,
|
|
|
SUM(CASE WHEN SENSMVT != 1 THEN QUANTITE::numeric ELSE 0 END) AS sortie_quantite,
|
|
|
SUM(VALHT::numeric * (CASE WHEN SENSMVT != 1 THEN 1 ELSE 0 END)) AS sortie_montant,
|
|
|
SUM(VALTTC::numeric * (CASE WHEN SENSMVT != 1 THEN 1 ELSE 0 END)) AS sortie_montant_ttc,
|
|
|
0.00 AS stock_quantite_fin,
|
|
|
0.00 AS stock_valeur_fin,
|
|
|
0.00 AS stock_valeur_fin_ttc
|
|
|
FROM w_MVTPDT mvtpdt
|
|
|
JOIN prod_pharma.PRODUIT ON PRODUIT.PRCLEUNIK = MVTPDT.PRCLEUNIK
|
|
|
JOIN eco.t_articles ON MVTPDT.PRCLEUNIK = t_articles.code_original
|
|
|
LEFT JOIN eco.t_divers ON t_divers.code = 'PHARMA_MAG_LIEU'
|
|
|
LEFT JOIN eco.t_sites ON CASE WHEN t_divers.valeur = '0' THEN COALESCE(MAGASIN::text,'0') ELSE '0' END = t_sites.code
|
|
|
LEFT JOIN eco.t_lieux ON CASE WHEN t_divers.valeur = '1' THEN COALESCE(MAGASIN::text,'0') ELSE PRODUIT.LIEUSTOCK END = 'XXX'-- t_lieux.code_original
|
|
|
WHERE TYPEMVT <> 3
|
|
|
GROUP BY 1,2,3,4,5,6,7,8,9,10,11,13
|
|
|
ORDER BY 1,2;
|
|
|
|
|
|
CREATE INDEX w_stocks_i1 ON w_stocks USING btree (article_id);
|
|
|
|
|
|
UPDATE w_stocks
|
|
|
SET entree_quantite_pump = 0, entree_montant_pump = 0
|
|
|
WHERE entree_quantite_pump < 0 OR entree_montant_pump < 0;
|
|
|
|
|
|
/* DELETE FROM w_stocks
|
|
|
WHERE article_id IN (
|
|
|
SELECT article_id
|
|
|
FROM w_stocks
|
|
|
WHERE MODEGEST = '4'
|
|
|
GROUP BY 1
|
|
|
HAVING MAX(date_debut) <= '[ENV_ECO_ANNEEDEBUT]1231'
|
|
|
);
|
|
|
|
|
|
DELETE FROM w_stocks
|
|
|
WHERE date_fin < '[ENV_ECO_ANNEEDEBUT]0101';
|
|
|
*/
|
|
|
|
|
|
SELECT base.cti_execute(
|
|
|
'INSERT INTO w_stocks
|
|
|
SELECT
|
|
|
w_stocks.article_id,
|
|
|
date(w_stocks.date_debut + interval ''2 month'' - interval ''1 day'') AS date_fin,
|
|
|
date(w_stocks.date_debut + interval ''1 month'') AS date_debut,
|
|
|
w_stocks.mois_sequence + 1 AS mois_sequence,
|
|
|
w_stocks.MODEGEST,
|
|
|
w_stocks.MAGASIN,
|
|
|
w_stocks.ucd_id,
|
|
|
w_stocks.lpp_id,
|
|
|
w_stocks.compte_id,
|
|
|
|
|
|
w_stocks.site_id,
|
|
|
w_stocks.lieu_id,
|
|
|
w_stocks.provider_id,
|
|
|
w_stocks.fournisseur_id,
|
|
|
|
|
|
0.00 AS stock_quantite_debut,
|
|
|
0.00 AS stock_valeur_debut,
|
|
|
0.00 AS stock_valeur_debut_ttc,
|
|
|
0.00 AS entree_quantite,
|
|
|
0.00 AS entree_montant,
|
|
|
0.00 AS entree_montant_ttc,
|
|
|
0.00 AS entree_quantite_pump,
|
|
|
0.00 AS entree_montant_pump,
|
|
|
0.00 AS entree_montant_pump_ttc,
|
|
|
|
|
|
0.00 AS pump,
|
|
|
0.00 AS pump_ttc,
|
|
|
|
|
|
0.00 AS sortie_quantite,
|
|
|
0.00 AS sortie_montant,
|
|
|
0.00 AS sortie_montant_ttc,
|
|
|
|
|
|
0.00 AS stock_quantite_fin,
|
|
|
0.00 AS stock_valeur_fin,
|
|
|
0.00 AS stock_valeur_fin_ttc
|
|
|
FROM w_stocks
|
|
|
LEFT JOIN w_stocks w_stocks_after ON
|
|
|
w_stocks_after.article_id = w_stocks.article_id AND
|
|
|
w_stocks_after.mois_sequence = w_stocks.mois_sequence + 1
|
|
|
WHERE w_stocks_after.article_id IS NULL AND
|
|
|
w_stocks.date_debut < date(date_trunc(''month'',now()))
|
|
|
ORDER BY 1,2',300);
|
|
|
|
|
|
|
|
|
-- Stock produit pour tous les magasins
|
|
|
DROP TABLE IF EXISTS w_correction;
|
|
|
CREATE TEMP TABLE w_correction AS
|
|
|
SELECT t_articles.oid AS article_id,
|
|
|
|
|
|
''::text AS MAGASIN,
|
|
|
PRODUIT.PRCLEUNIK,
|
|
|
MAX(STOCK::numeric) AS STOCK,
|
|
|
SUM(COALESCE(CASE WHEN SENSMVT = 1 THEN QUANTITE::numeric ELSE -QUANTITE::numeric END,0)) AS quantite_mvt,
|
|
|
MAX(STOCK::numeric) - SUM(COALESCE(CASE WHEN SENSMVT = 1 THEN QUANTITE::numeric ELSE -QUANTITE::numeric END,0)) AS correction_quantite_fin,
|
|
|
'P'::text AS source
|
|
|
FROM prod_pharma.PRODUIT
|
|
|
JOIN eco.t_articles ON PRODUIT.PRCLEUNIK = t_articles.code_original
|
|
|
LEFT JOIN w_MVTPDT ON w_MVTPDT.PRCLEUNIK = PRODUIT.PRCLEUNIK
|
|
|
WHERE STOCK IS NOT NULL
|
|
|
GROUP BY 1,2,3
|
|
|
HAVING MAX(STOCK::numeric) <> SUM(COALESCE(CASE WHEN SENSMVT = 1 THEN QUANTITE::numeric ELSE -QUANTITE::numeric END,0))
|
|
|
|
|
|
;
|
|
|
|
|
|
|
|
|
-- Stock produit par magasin
|
|
|
SELECT base.cti_execute('
|
|
|
INSERT INTO w_correction
|
|
|
SELECT t_articles.oid AS article_id,
|
|
|
STKPDT.MAGASIN,
|
|
|
STKPDT.PRCLEUNIK,
|
|
|
STKPDT.STOCK,
|
|
|
quantite_mvt,
|
|
|
STKPDT.STOCK - quantite_mvt AS correction_quantite_fin,
|
|
|
''S''::text AS source
|
|
|
FROM prod_pharma.STKPDT
|
|
|
JOIN (SELECT
|
|
|
MAGASIN,
|
|
|
PRCLEUNIK,
|
|
|
SUM(COALESCE(QUANTITE::numeric * (CASE
|
|
|
WHEN SENSMVT = 1 THEN 1
|
|
|
ELSE -1 END) ,0)) AS quantite_mvt
|
|
|
FROM w_MVTPDT
|
|
|
GROUP BY 1,2) w_MVTPDT ON
|
|
|
w_MVTPDT.PRCLEUNIK = STKPDT.PRCLEUNIK AND
|
|
|
w_MVTPDT.MAGASIN = STKPDT.MAGASIN
|
|
|
JOIN eco.t_articles ON STKPDT.PRCLEUNIK = t_articles.code_original
|
|
|
WHERE STKPDT.STOCK IS NOT NULL AND STKPDT.STOCK - quantite_mvt != 0',1)
|
|
|
WHERE (SELECT count(*) FROM information_schema.columns WHERE table_name = 'stkpdt') > 0
|
|
|
;
|
|
|
|
|
|
-- Par magasin en priorité
|
|
|
DELETE
|
|
|
FROM w_correction
|
|
|
WHERE source = 'P' AND
|
|
|
(SELECT count(*) FROM w_correction WHERE source = 'S') > 0
|
|
|
;
|
|
|
|
|
|
DROP TABLE IF EXISTS w_stocks_fin;
|
|
|
CREATE TEMP TABLE w_stocks_fin AS
|
|
|
SELECT w_stocks.article_id,
|
|
|
w_stocks.date_fin,
|
|
|
w_stocks.MAGASIN,
|
|
|
SUM(w_stocks_before.entree_quantite-w_stocks_before.sortie_quantite) AS stock_quantite_fin_base,
|
|
|
COALESCE(correction_quantite_fin,0) AS correction_quantite,
|
|
|
SUM(w_stocks_before.entree_quantite-w_stocks_before.sortie_quantite) + COALESCE(correction_quantite_fin,0) AS stock_quantite_fin,
|
|
|
base.cti_division(
|
|
|
SUM(w_stocks_before.entree_montant_pump)::numeric
|
|
|
,
|
|
|
SUM(w_stocks_before.entree_quantite_pump)::numeric
|
|
|
) AS pump,
|
|
|
base.cti_division(
|
|
|
SUM(w_stocks_before.entree_montant_pump_ttc)::numeric
|
|
|
,
|
|
|
SUM(w_stocks_before.entree_quantite_pump)::numeric
|
|
|
) AS pump_ttc,
|
|
|
base.cti_division(
|
|
|
SUM(CASE WHEN w_stocks.mois_sequence - w_stocks_before.mois_sequence < 6 THEN w_stocks_before.entree_montant_pump ELSE 0 END)::numeric
|
|
|
,
|
|
|
SUM(CASE WHEN w_stocks.mois_sequence - w_stocks_before.mois_sequence < 6 THEN w_stocks_before.entree_quantite_pump ELSE 0 END)::numeric
|
|
|
) AS pump6,
|
|
|
base.cti_division(
|
|
|
SUM(CASE WHEN w_stocks.mois_sequence - w_stocks_before.mois_sequence < 6 THEN w_stocks_before.entree_montant_pump_ttc ELSE 0 END)::numeric
|
|
|
,
|
|
|
SUM(CASE WHEN w_stocks.mois_sequence - w_stocks_before.mois_sequence < 6 THEN w_stocks_before.entree_quantite_pump ELSE 0 END)::numeric
|
|
|
) AS pump6_ttc,
|
|
|
base.cti_division(
|
|
|
SUM(CASE WHEN w_stocks.mois_sequence - w_stocks_before.mois_sequence < 12 THEN w_stocks_before.entree_montant_pump ELSE 0 END)::numeric
|
|
|
,
|
|
|
SUM(CASE WHEN w_stocks.mois_sequence - w_stocks_before.mois_sequence < 12 THEN w_stocks_before.entree_quantite_pump ELSE 0 END)::numeric
|
|
|
) AS pump12,
|
|
|
base.cti_division(
|
|
|
SUM(CASE WHEN w_stocks.mois_sequence - w_stocks_before.mois_sequence < 12 THEN w_stocks_before.entree_montant_pump_ttc ELSE 0 END)::numeric
|
|
|
,
|
|
|
SUM(CASE WHEN w_stocks.mois_sequence - w_stocks_before.mois_sequence < 12 THEN w_stocks_before.entree_quantite_pump ELSE 0 END)::numeric
|
|
|
) AS pump12_ttc
|
|
|
FROM w_stocks
|
|
|
JOIN w_stocks w_stocks_before ON
|
|
|
w_stocks.MAGASIN = w_stocks_before.MAGASIN AND
|
|
|
w_stocks.article_id = w_stocks_before.article_id AND
|
|
|
w_stocks.date_fin >= w_stocks_before.date_fin
|
|
|
LEFT JOIN w_correction ON
|
|
|
w_correction.article_id = w_stocks.article_id AND
|
|
|
(
|
|
|
w_correction.MAGASIN = w_stocks.MAGASIN OR
|
|
|
w_correction.MAGASIN = ''
|
|
|
)
|
|
|
GROUP BY 1,2,3,5;
|
|
|
|
|
|
CREATE INDEX w_stocks_fin_i1 ON w_stocks_fin USING btree (article_id);
|
|
|
|
|
|
|
|
|
|
|
|
UPDATE w_stocks SET
|
|
|
pump = CASE WHEN pump6 <> 0 THEN pump6 WHEN pump12 <> 0 THEN pump12 ELSE w_stocks_fin.pump END,
|
|
|
pump_ttc = CASE WHEN pump6_ttc <> 0 THEN pump6_ttc WHEN pump12_ttc <> 0 THEN pump12_ttc ELSE w_stocks_fin.pump_ttc END,
|
|
|
stock_quantite_fin = w_stocks_fin.stock_quantite_fin,
|
|
|
stock_valeur_fin = w_stocks_fin.stock_quantite_fin * CASE WHEN pump6 <> 0 THEN pump6 WHEN pump12 <> 0 THEN pump12 ELSE w_stocks_fin.pump END,
|
|
|
stock_valeur_fin_ttc = w_stocks_fin.stock_quantite_fin * CASE WHEN pump6_ttc <> 0 THEN pump6_ttc WHEN pump12_ttc <> 0 THEN pump12 ELSE w_stocks_fin.pump_ttc END
|
|
|
FROM w_stocks_fin
|
|
|
WHERE w_stocks_fin.article_id = w_stocks.article_id AND
|
|
|
w_stocks_fin.date_fin = w_stocks.date_fin;
|
|
|
|
|
|
-- Autres règles de valorisation des stocks
|
|
|
|
|
|
INSERT INTO eco.t_divers (code, texte, valeur, description)
|
|
|
SELECT
|
|
|
'NO_CALC_PUMP',
|
|
|
'Valorisation des stocks',
|
|
|
'0',
|
|
|
'0:Selon les entrées, 1:Selon la dernière distribution, 2:???'
|
|
|
WHERE 'NO_CALC_PUMP' NOT IN (SELECT code FROM eco.t_divers)
|
|
|
;
|
|
|
|
|
|
UPDATE eco.t_divers SET
|
|
|
texte = 'Valorisation des stocks',
|
|
|
description = '0:Selon les entrées, 1:Selon la dernière distribution, 2:???'
|
|
|
WHERE code = 'NO_CALC_PUMP' AND
|
|
|
(
|
|
|
texte <> 'Valorisation des stocks' OR
|
|
|
description <> '0:Selon les entrées, 1:Selon la moyenne des sorties, 2:???, 3:Selon la dernière sortie'
|
|
|
)
|
|
|
;
|
|
|
|
|
|
-- Pharma n'historise pas le PUMP.
|
|
|
-- On reconstitue donc l'historique selon les mouvements de distribution, cela permet d'avoir la même valorisation qua PHARMA
|
|
|
DROP TABLE IF EXISTS w_MVTPDP_distri;
|
|
|
CREATE TEMP TABLE w_MVTPDP_distri AS
|
|
|
SELECT MAGASIN,
|
|
|
PRCLEUNIK,
|
|
|
date(DATE_TRUNC('month',DATEMVT)) AS DATEMVT_mois,
|
|
|
date(DATE_TRUNC('month',DATEMVT) + interval '1 month' - interval '1 day') AS DATEMVT_mois_fin,
|
|
|
rank() OVER (PARTITION BY MAGASIN, PRCLEUNIK ORDER BY date(DATE_TRUNC('month',DATEMVT)) ) AS DATEMVT_rank,
|
|
|
MAX(t_articles.oid) AS article_id,
|
|
|
(MAX(ARRAY[DATEMVT::text, base.cti_division(VALTTC::numeric,QUANTITE::numeric)::text]))[2]::numeric AS PUMP_distri_ttc,
|
|
|
(MAX(ARRAY[DATEMVT::text, base.cti_division(VALHT::numeric,QUANTITE::numeric)::text]))[2]::numeric AS PUMP_distri_ht,
|
|
|
SUM(QUANTITE) AS QUANTITE_distri
|
|
|
FROM w_MVTPDT
|
|
|
JOIN eco.t_articles ON PRCLEUNIK = t_articles.code_original
|
|
|
JOIN eco.t_divers ON t_divers.code = 'NO_CALC_PUMP' AND t_divers.valeur = '1'
|
|
|
WHERE SENSMVT = 2 AND
|
|
|
QUANTITE > 0 AND
|
|
|
VALTTC > 0 AND
|
|
|
TYPESORTIE IN ('DG','DN','DS')
|
|
|
GROUP BY 1,2,3,4
|
|
|
ORDER BY 1,2,3
|
|
|
;
|
|
|
|
|
|
ANALYSE w_MVTPDP_distri
|
|
|
;
|
|
|
|
|
|
CREATE INDEX i_w_MVTPDP_distri_1
|
|
|
ON w_MVTPDP_distri
|
|
|
USING btree
|
|
|
(PRCLEUNIK)
|
|
|
;
|
|
|
|
|
|
UPDATE w_MVTPDP_distri
|
|
|
SET DATEMVT_mois_fin = date(w_MVTPDP_distri1.DATEMVT_mois - interval '1 day')
|
|
|
FROm w_MVTPDP_distri w_MVTPDP_distri1
|
|
|
WHERE w_MVTPDP_distri.PRCLEUNIK = w_MVTPDP_distri1.PRCLEUNIK AND
|
|
|
w_MVTPDP_distri.DATEMVT_rank = w_MVTPDP_distri1.DATEMVT_rank -1 AND
|
|
|
w_MVTPDP_distri.DATEMVT_mois_fin <> date(w_MVTPDP_distri1.DATEMVT_mois - interval '1 day')
|
|
|
;
|
|
|
|
|
|
UPDATE w_MVTPDP_distri
|
|
|
SET DATEMVT_mois_fin = date(date_trunc('month',now()) + interval '1 month' - interval '1 day')
|
|
|
FROM
|
|
|
(
|
|
|
SELECT MAGASIN, PRCLEUNIK, MAX(DATEMVT_rank) AS DATEMVT_rank
|
|
|
FROM w_MVTPDP_distri
|
|
|
GROUP BY 1,2
|
|
|
HAVING MAX(DATEMVT_mois_fin) < date(now())
|
|
|
) subview
|
|
|
WHERE w_MVTPDP_distri.PRCLEUNIK = subview.PRCLEUNIK AND
|
|
|
w_MVTPDP_distri.MAGASIN = subview.MAGASIN AND
|
|
|
w_MVTPDP_distri.DATEMVT_rank = subview.DATEMVT_rank
|
|
|
;
|
|
|
|
|
|
|
|
|
UPDATE w_stocks
|
|
|
SET
|
|
|
stock_valeur_debut = stock_quantite_debut * PUMP_distri_ht,
|
|
|
stock_valeur_debut_ttc = stock_quantite_debut * PUMP_distri_ttc,
|
|
|
stock_valeur_fin = stock_quantite_fin * PUMP_distri_ht,
|
|
|
stock_valeur_fin_ttc = stock_quantite_fin * PUMP_distri_ttc,
|
|
|
pump = PUMP_distri_ht,
|
|
|
pump_ttc = PUMP_distri_ttc
|
|
|
FROM w_MVTPDP_distri
|
|
|
WHERE 1=1
|
|
|
AND w_stocks.article_id = w_MVTPDP_distri.article_id
|
|
|
AND w_stocks.MAGASIN = w_MVTPDP_distri.MAGASIN
|
|
|
AND w_stocks.date_debut BETWEEN w_MVTPDP_distri.DATEMVT_mois AND w_MVTPDP_distri.DATEMVT_mois_fin
|
|
|
;
|
|
|
|
|
|
|
|
|
DELETE FROM w_stocks
|
|
|
WHERE article_id IN (
|
|
|
SELECT article_id
|
|
|
FROM w_stocks
|
|
|
WHERE stock_quantite_fin <> 0
|
|
|
GROUP BY 1
|
|
|
HAVING MAX(date_debut) <= '[ENV_ECO_ANNEEDEBUT]1231'
|
|
|
);
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
UPDATE w_stocks SET
|
|
|
stock_quantite_debut = w_stocks_before.stock_quantite_fin,
|
|
|
stock_valeur_debut = w_stocks_before.stock_valeur_fin,
|
|
|
stock_valeur_debut_ttc = w_stocks_before.stock_valeur_fin_ttc
|
|
|
FROM w_stocks w_stocks_before
|
|
|
WHERE w_stocks_before.article_id = w_stocks.article_id AND
|
|
|
w_stocks_before.MAGASIN = w_stocks.MAGASIN AND
|
|
|
w_stocks_before.mois_sequence = w_stocks.mois_sequence - 1;
|
|
|
|
|
|
|
|
|
SELECT base.cti_disable_index('eco', 'i_stock_1');
|
|
|
SELECT base.cti_disable_index('eco', 'i_stock_2');
|
|
|
SELECT base.cti_disable_index('eco', 'i_stock_3');
|
|
|
SELECT base.cti_disable_index('eco', 'i_stock_4');
|
|
|
SELECT base.cti_disable_index('eco', 'i_stock_5');
|
|
|
|
|
|
|
|
|
TRUNCATE eco.p_stock;
|
|
|
|
|
|
INSERT INTO eco.p_stock(
|
|
|
article_id,
|
|
|
date_fin,
|
|
|
date_debut,
|
|
|
ucd_id,
|
|
|
lpp_id,
|
|
|
compte_id,
|
|
|
lieu_id,
|
|
|
site_id,
|
|
|
provider_id,
|
|
|
fournisseur_id,
|
|
|
stock_quantite_debut,
|
|
|
stock_valeur_debut,
|
|
|
stock_valeur_debut_ttc,
|
|
|
entree_quantite,
|
|
|
entree_montant,
|
|
|
entree_montant_ttc,
|
|
|
pump,
|
|
|
pump_ttc,
|
|
|
sortie_quantite,
|
|
|
sortie_montant,
|
|
|
sortie_montant_ttc,
|
|
|
stock_quantite_fin,
|
|
|
stock_valeur_fin,
|
|
|
stock_valeur_fin_ttc)
|
|
|
|
|
|
SELECT
|
|
|
article_id,
|
|
|
date_fin,
|
|
|
date_debut,
|
|
|
ucd_id,
|
|
|
lpp_id,
|
|
|
compte_id,
|
|
|
lieu_id,
|
|
|
site_id,
|
|
|
provider_id,
|
|
|
fournisseur_id,
|
|
|
|
|
|
stock_quantite_debut,
|
|
|
stock_valeur_debut,
|
|
|
stock_valeur_debut_ttc,
|
|
|
entree_quantite,
|
|
|
entree_montant,
|
|
|
entree_montant_ttc,
|
|
|
pump,
|
|
|
pump_ttc,
|
|
|
sortie_quantite,
|
|
|
sortie_montant,
|
|
|
sortie_montant_ttc,
|
|
|
stock_quantite_fin,
|
|
|
stock_valeur_fin,
|
|
|
stock_valeur_fin_ttc
|
|
|
FROM w_stocks
|
|
|
WHERE date_debut >= '[ENV_ECO_ANNEEDEBUT]0101';
|
|
|
|
|
|
SELECT base.cti_enable_index('eco', 'i_stock_1');
|
|
|
SELECT base.cti_enable_index('eco', 'i_stock_2');
|
|
|
SELECT base.cti_enable_index('eco', 'i_stock_3');
|
|
|
SELECT base.cti_enable_index('eco', 'i_stock_4');
|
|
|
SELECT base.cti_enable_index('eco', 'i_stock_5');
|
|
|
|
|
|
]]></sqlcmd>
|
|
|
</NODE>
|
|
|
|
|
|
<NODE label="Mouvements">
|
|
|
<sqlcmd><![CDATA[
|
|
|
|
|
|
|
|
|
SELECT base.cti_execute('
|
|
|
UPDATE w_MVTPDT
|
|
|
SET C1CLEUNIK = COMMANDE_REG.C1CLEUNIK
|
|
|
FROM w_COMMANDE
|
|
|
JOIN w_COMMANDE COMMANDE_REG ON COMMANDE_REG.NUMCMDE::text || COMMANDE_REG.SUFCMDE::text = w_COMMANDE.NUMCMDEREG
|
|
|
WHERE w_MVTPDT.C1CLEUNIK > 0 AND w_MVTPDT.C1CLEUNIK NOT IN (SELECT code_original FROM eco.p_commandes) AND TYPEMVT = 1 AND
|
|
|
w_COMMANDE.C1CLEUNIK = w_MVTPDT.C1CLEUNIK',20);
|
|
|
|
|
|
SELECT base.cti_execute('
|
|
|
UPDATE w_MVTPDT
|
|
|
SET C1CLEUNIK = COMMANDE_REG.C1CLEUNIK
|
|
|
FROM w_COMMANDE
|
|
|
JOIN w_COMMANDE COMMANDE_REG ON COMMANDE_REG.NUMCMDE::text || COMMANDE_REG.SUFCMDE::text = w_COMMANDE.NUMCMDEREG
|
|
|
WHERE w_MVTPDT.C1CLEUNIK > 0 AND w_MVTPDT.C1CLEUNIK NOT IN (SELECT code_original FROM eco.p_commandes) AND TYPEMVT = 3 AND
|
|
|
w_COMMANDE.C1CLEUNIK = w_MVTPDT.C1CLEUNIK',20);
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
DROP TABLE IF EXISTS w_MVTPDT_art;
|
|
|
CREATE TEMP TABLE w_MVTPDT_art (C1CLEUNIK bigint, PRCLEUNIK bigint, DATEMVT date, QUANTITE numeric, VALTTC numeric, oid bigint);
|
|
|
CREATE INDEX w_MVTPDT_art_i1 ON w_MVTPDT_art USING btree (oid);
|
|
|
CREATE INDEX w_MVTPDT_art_i2 ON w_MVTPDT_art USING btree (PRCLEUNIK);
|
|
|
CREATE INDEX w_MVTPDT_art_i3 ON w_MVTPDT_art USING btree (C1CLEUNIK);
|
|
|
|
|
|
DROP TABLE IF EXISTS w_LIGNE_art;
|
|
|
CREATE TEMP TABLE w_LIGNE_art (C1CLEUNIK bigint, PRCLEUNIK bigint, DATELIVCMD date, QTELIV numeric, FACTTTC numeric, nb numeric, L0CLEUNIK bigint);
|
|
|
CREATE INDEX w_LIGNE_art_i1 ON w_LIGNE_art USING btree (C1CLEUNIK);
|
|
|
CREATE INDEX w_LIGNE_art_i2 ON w_LIGNE_art USING btree (PRCLEUNIK);
|
|
|
CREATE INDEX w_LIGNE_art_i3 ON w_LIGNE_art USING btree (L0CLEUNIK);
|
|
|
|
|
|
SELECT base.cti_execute('
|
|
|
TRUNCATE w_MVTPDT_art.,
|
|
|
INSERT INTO w_MVTPDT_art
|
|
|
SELECT C1CLEUNIK, PRCLEUNIK, null , 0, 0, MIN(oid) AS oid
|
|
|
FROM w_MVTPDT
|
|
|
WHERE L0CLEUNIK <= 0 AND C1CLEUNIK <> 0 AND TYPEMVT = 1
|
|
|
GROUP BY 1,2.,
|
|
|
|
|
|
TRUNCATE w_LIGNE_art.,
|
|
|
INSERT INTO w_LIGNE_art
|
|
|
SELECT w_COMMANDE.C1CLEUNIK, PRCLEUNIK, null , 0, 0, count(*), MIN(L0CLEUNIK) AS L0CLEUNIK
|
|
|
FROM w_COMMANDE
|
|
|
JOIN eco.p_commandes ON w_COMMANDE.C1CLEUNIK = code_original
|
|
|
JOIN w_LIGNE_source LIGNE ON w_COMMANDE.C1CLEUNIK = LIGNE.C1CLEUNIK
|
|
|
WHERE QTELIV <> 0
|
|
|
GROUP BY 1,2
|
|
|
HAVING count(*) = 1.,
|
|
|
|
|
|
UPDATE w_MVTPDT
|
|
|
SET L0CLEUNIK = w_LIGNE_art.L0CLEUNIK
|
|
|
FROM w_MVTPDT_art
|
|
|
JOIN w_LIGNE_art ON w_MVTPDT_art.C1CLEUNIK = w_LIGNE_art.C1CLEUNIK AND
|
|
|
w_MVTPDT_art.PRCLEUNIK = w_LIGNE_art.PRCLEUNIK AND
|
|
|
w_LIGNE_art.nb = 1
|
|
|
WHERE w_MVTPDT_art.oid = w_MVTPDT.oid',100);
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
SELECT base.cti_execute('
|
|
|
TRUNCATE w_MVTPDT_art.,
|
|
|
INSERT INTO w_MVTPDT_art
|
|
|
SELECT C1CLEUNIK, PRCLEUNIK, date(DATEMVT) AS DATEMVT, QUANTITE::numeric, VALTTC::numeric, MIN(oid) AS oid
|
|
|
FROM w_MVTPDT
|
|
|
WHERE L0CLEUNIK <= 0 AND C1CLEUNIK <> 0 AND TYPEMVT = 1
|
|
|
GROUP BY 1,2,3,4,5.,
|
|
|
|
|
|
TRUNCATE w_LIGNE_art.,
|
|
|
INSERT INTO w_LIGNE_art
|
|
|
SELECT w_COMMANDE.C1CLEUNIK, LIGNE.PRCLEUNIK, date(DATELIVCMD) AS DATELIVCMD, QTELIV::numeric, CASE WHEN FACTTTC <> 0 THEN FACTTTC ELSE VALEURTTC END AS FACTTTC, count(*), MIN(LIGNE.L0CLEUNIK) AS L0CLEUNIK
|
|
|
FROM w_COMMANDE
|
|
|
JOIN eco.p_commandes ON w_COMMANDE.C1CLEUNIK = code_original
|
|
|
JOIN w_LIGNE_source LIGNE ON w_COMMANDE.C1CLEUNIK = LIGNE.C1CLEUNIK
|
|
|
LEFT JOIN w_MVTPDT ON LIGNE.L0CLEUNIK = w_MVTPDT.L0CLEUNIK
|
|
|
WHERE QTELIV <> 0 AND w_MVTPDT.L0CLEUNIK IS NULL
|
|
|
GROUP BY 1,2,3,4,5.,
|
|
|
|
|
|
UPDATE w_MVTPDT
|
|
|
SET L0CLEUNIK = w_LIGNE_art.L0CLEUNIK
|
|
|
FROM w_MVTPDT_art
|
|
|
JOIN w_LIGNE_art ON w_MVTPDT_art.C1CLEUNIK = w_LIGNE_art.C1CLEUNIK AND
|
|
|
w_MVTPDT_art.PRCLEUNIK = w_LIGNE_art.PRCLEUNIK AND
|
|
|
w_MVTPDT_art.DATEMVT = w_LIGNE_art.DATELIVCMD AND
|
|
|
w_MVTPDT_art.QUANTITE = w_LIGNE_art.QTELIV AND
|
|
|
w_MVTPDT_art.VALTTC = w_LIGNE_art.FACTTTC
|
|
|
WHERE w_MVTPDT_art.oid = w_MVTPDT.oid',100);
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
SELECT base.cti_execute('
|
|
|
TRUNCATE w_MVTPDT_art.,
|
|
|
INSERT INTO w_MVTPDT_art
|
|
|
SELECT C1CLEUNIK, PRCLEUNIK, date(DATEMVT) AS DATEMVT, QUANTITE::numeric, 0, MIN(oid) AS oid
|
|
|
FROM w_MVTPDT
|
|
|
WHERE L0CLEUNIK <= 0 AND C1CLEUNIK <> 0 AND TYPEMVT = 1
|
|
|
GROUP BY 1,2,3,4.,
|
|
|
|
|
|
TRUNCATE w_LIGNE_art.,
|
|
|
INSERT INTO w_LIGNE_art
|
|
|
SELECT w_COMMANDE.C1CLEUNIK, LIGNE.PRCLEUNIK, date(DATELIVCMD) AS DATELIVCMD, QTELIV::numeric, 0, count(*), MIN(LIGNE.L0CLEUNIK) AS L0CLEUNIK
|
|
|
FROM w_COMMANDE
|
|
|
JOIN eco.p_commandes ON w_COMMANDE.C1CLEUNIK = code_original
|
|
|
JOIN w_LIGNE_source LIGNE ON w_COMMANDE.C1CLEUNIK = LIGNE.C1CLEUNIK
|
|
|
LEFT JOIN w_MVTPDT ON LIGNE.L0CLEUNIK = w_MVTPDT.L0CLEUNIK
|
|
|
WHERE QTELIV <> 0 AND w_MVTPDT.L0CLEUNIK IS NULL
|
|
|
GROUP BY 1,2,3,4.,
|
|
|
|
|
|
UPDATE w_MVTPDT
|
|
|
SET L0CLEUNIK = w_LIGNE_art.L0CLEUNIK
|
|
|
FROM w_MVTPDT_art
|
|
|
JOIN w_LIGNE_art ON w_MVTPDT_art.C1CLEUNIK = w_LIGNE_art.C1CLEUNIK AND
|
|
|
w_MVTPDT_art.PRCLEUNIK = w_LIGNE_art.PRCLEUNIK AND
|
|
|
w_MVTPDT_art.DATEMVT = w_LIGNE_art.DATELIVCMD AND
|
|
|
w_MVTPDT_art.QUANTITE = w_LIGNE_art.QTELIV
|
|
|
WHERE w_MVTPDT_art.oid = w_MVTPDT.oid',100);
|
|
|
|
|
|
|
|
|
SELECT base.cti_execute('
|
|
|
TRUNCATE w_MVTPDT_art.,
|
|
|
INSERT INTO w_MVTPDT_art
|
|
|
SELECT C1CLEUNIK, PRCLEUNIK, NULL::date AS DATEMVT, QUANTITE::numeric, 0, MIN(oid) AS oid
|
|
|
FROM w_MVTPDT
|
|
|
WHERE L0CLEUNIK <= 0 AND C1CLEUNIK <> 0 AND TYPEMVT = 1
|
|
|
GROUP BY 1,2,3,4.,
|
|
|
|
|
|
TRUNCATE w_LIGNE_art.,
|
|
|
INSERT INTO w_LIGNE_art
|
|
|
SELECT w_COMMANDE.C1CLEUNIK, LIGNE.PRCLEUNIK, NULL::date AS DATELIVCMD, QTELIV::numeric, 0, count(*), MIN(LIGNE.L0CLEUNIK) AS L0CLEUNIK
|
|
|
FROM w_COMMANDE
|
|
|
JOIN eco.p_commandes ON w_COMMANDE.C1CLEUNIK = code_original
|
|
|
JOIN w_LIGNE_source LIGNE ON w_COMMANDE.C1CLEUNIK = LIGNE.C1CLEUNIK
|
|
|
LEFT JOIN w_MVTPDT ON LIGNE.L0CLEUNIK = w_MVTPDT.L0CLEUNIK
|
|
|
WHERE QTELIV <> 0 AND w_MVTPDT.L0CLEUNIK IS NULL
|
|
|
GROUP BY 1,2,3,4.,
|
|
|
|
|
|
UPDATE w_MVTPDT
|
|
|
SET L0CLEUNIK = w_LIGNE_art.L0CLEUNIK
|
|
|
FROM w_MVTPDT_art
|
|
|
JOIN w_LIGNE_art ON w_MVTPDT_art.C1CLEUNIK = w_LIGNE_art.C1CLEUNIK AND
|
|
|
w_MVTPDT_art.PRCLEUNIK = w_LIGNE_art.PRCLEUNIK AND
|
|
|
w_MVTPDT_art.QUANTITE = w_LIGNE_art.QTELIV
|
|
|
WHERE w_MVTPDT_art.oid = w_MVTPDT.oid',100);
|
|
|
|
|
|
|
|
|
|
|
|
SELECT base.cti_execute('
|
|
|
TRUNCATE w_MVTPDT_art.,
|
|
|
INSERT INTO w_MVTPDT_art
|
|
|
SELECT C1CLEUNIK, PRCLEUNIK, null , 0, 0, MIN(oid) AS oid
|
|
|
FROM w_MVTPDT
|
|
|
WHERE L0CLEUNIK <= 0 AND C1CLEUNIK <> 0 AND TYPEMVT = 1
|
|
|
GROUP BY 1,2.,
|
|
|
|
|
|
TRUNCATE w_LIGNE_art.,
|
|
|
INSERT INTO w_LIGNE_art
|
|
|
SELECT w_COMMANDE.C1CLEUNIK, PRCLEUNIK, null , 0, 0, count(*), MIN(L0CLEUNIK) AS L0CLEUNIK
|
|
|
FROM w_COMMANDE
|
|
|
JOIN eco.p_commandes ON w_COMMANDE.C1CLEUNIK = code_original
|
|
|
JOIN w_LIGNE_source LIGNE ON w_COMMANDE.C1CLEUNIK = LIGNE.C1CLEUNIK
|
|
|
GROUP BY 1,2
|
|
|
HAVING count(*) = 1.,
|
|
|
|
|
|
UPDATE w_MVTPDT
|
|
|
SET L0CLEUNIK = w_LIGNE_art.L0CLEUNIK
|
|
|
FROM w_MVTPDT_art
|
|
|
JOIN w_LIGNE_art ON w_MVTPDT_art.C1CLEUNIK = w_LIGNE_art.C1CLEUNIK AND
|
|
|
w_MVTPDT_art.PRCLEUNIK = w_LIGNE_art.PRCLEUNIK AND
|
|
|
w_LIGNE_art.nb = 1
|
|
|
WHERE w_MVTPDT_art.oid = w_MVTPDT.oid',100);
|
|
|
|
|
|
|
|
|
|
|
|
UPDATE w_MVTPDT
|
|
|
SET SERVICE = LIGNE.SERVICE,
|
|
|
profil_code_original = CASE WHEN LIGNE.SERVICE <> '' AND LIGNE.SERVICE <> '-1' THEN '|' || LIGNE.SERVICE ELSE '' END
|
|
|
FROM w_LIGNE_source LIGNE
|
|
|
WHERE w_MVTPDT.L0CLEUNIK = LIGNE.L0CLEUNIK AND LIGNE.SERVICE <> '' AND LIGNE.SERVICE <> '-1';
|
|
|
|
|
|
|
|
|
|
|
|
TRUNCATE eco.t_profils_comptables;
|
|
|
|
|
|
INSERT INTO eco.t_profils_comptables
|
|
|
(code_original,
|
|
|
centre_responsabilite_id,
|
|
|
unite_fonctionnelle_id)
|
|
|
SELECT
|
|
|
profil_code_original AS code_original,
|
|
|
COALESCE(t_centres_responsabilites.oid,0) AS centre_responsabilite_id,
|
|
|
COALESCE(t_unites_fonctionnelles.oid,0) AS unite_fonctionnelle_id
|
|
|
FROM w_MVTPDT
|
|
|
LEFT JOIN eco.t_centres_responsabilites ON '0' = t_centres_responsabilites.code_original
|
|
|
LEFT JOIN eco.t_unites_fonctionnelles ON SERVICE = t_unites_fonctionnelles.code_original
|
|
|
GROUP BY 1,2,3;
|
|
|
|
|
|
UPDATE eco.t_profils_comptables SET
|
|
|
centre_responsabilite_code = t_centres_responsabilites.code,
|
|
|
centre_responsabilite_texte = t_centres_responsabilites.texte_court,
|
|
|
centre_responsabilite_section_id = t_centres_responsabilites.section_id,
|
|
|
centre_responsabilite_section_code = t_centres_responsabilites.section_code,
|
|
|
centre_responsabilite_section_texte = t_centres_responsabilites.section_texte,
|
|
|
|
|
|
unite_fonctionnelle_code = t_unites_fonctionnelles.code,
|
|
|
unite_fonctionnelle_texte = t_unites_fonctionnelles.texte_court,
|
|
|
unite_fonctionnelle_section_id = t_unites_fonctionnelles.section_id,
|
|
|
unite_fonctionnelle_section_code = t_unites_fonctionnelles.section_code,
|
|
|
unite_fonctionnelle_section_texte = t_unites_fonctionnelles.section_texte
|
|
|
FROM
|
|
|
eco.t_centres_responsabilites,
|
|
|
eco.t_unites_fonctionnelles
|
|
|
WHERE centre_responsabilite_id = t_centres_responsabilites.oid
|
|
|
AND unite_fonctionnelle_id = t_unites_fonctionnelles.oid
|
|
|
AND (
|
|
|
centre_responsabilite_code IS DISTINCT FROM t_centres_responsabilites.code OR
|
|
|
centre_responsabilite_texte IS DISTINCT FROM t_centres_responsabilites.texte_court OR
|
|
|
centre_responsabilite_section_id IS DISTINCT FROM t_centres_responsabilites.section_id OR
|
|
|
centre_responsabilite_section_code IS DISTINCT FROM t_centres_responsabilites.section_code OR
|
|
|
centre_responsabilite_section_texte IS DISTINCT FROM t_centres_responsabilites.section_texte OR
|
|
|
|
|
|
unite_fonctionnelle_code IS DISTINCT FROM t_unites_fonctionnelles.code OR
|
|
|
unite_fonctionnelle_texte IS DISTINCT FROM t_unites_fonctionnelles.texte_court OR
|
|
|
unite_fonctionnelle_section_id IS DISTINCT FROM t_unites_fonctionnelles.section_id OR
|
|
|
unite_fonctionnelle_section_code IS DISTINCT FROM t_unites_fonctionnelles.section_code OR
|
|
|
unite_fonctionnelle_section_texte IS DISTINCT FROM t_unites_fonctionnelles.section_texte
|
|
|
);
|
|
|
|
|
|
|
|
|
|
|
|
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');
|
|
|
|
|
|
|
|
|
INSERT INTO eco.p_mouvements_articles(
|
|
|
code_original,
|
|
|
date,
|
|
|
sens_mouvement,
|
|
|
type_mouvement_id,
|
|
|
texte,
|
|
|
gestionnaire_id,
|
|
|
site_id,
|
|
|
lieu_id,
|
|
|
profil_comptable_id,
|
|
|
article_id,
|
|
|
compte_id,
|
|
|
ucd_id,
|
|
|
lpp_id,
|
|
|
unite_fonctionnelle_id,
|
|
|
fournisseur_id,
|
|
|
commande_id,
|
|
|
ligne_commande,
|
|
|
prix_unitaire,
|
|
|
entree_quantite,
|
|
|
sortie_quantite,
|
|
|
entree_montant,
|
|
|
sortie_montant,
|
|
|
entree_montant_ht,
|
|
|
sortie_montant_ht,
|
|
|
sortie_montant_original_ttc,
|
|
|
sortie_montant_original_ht,
|
|
|
stock_quantite_debut,
|
|
|
stock_quantite_fin,
|
|
|
taux_prorata_tva,
|
|
|
no_patient,
|
|
|
no_sejour)
|
|
|
|
|
|
SELECT
|
|
|
MVTCLEUNIK::text AS code_original,
|
|
|
date(DATEMVT) AS date,
|
|
|
CASE WHEN SENSMVT = '1' THEN 'E' ELSE 'S' END AS sens_mouvement,
|
|
|
COALESCE(t_types_mouvements.oid,0) AS type_mouvement_id,
|
|
|
substr(TRIM(REFMVT1 || ' ' || REFMVT2 || ' ' || REFMVT3 || ' ' || MOTIF),1,255) 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_profils_comptables.oid,0) AS profil_comptable,
|
|
|
COALESCE(t_articles.oid,0) AS article_id,
|
|
|
COALESCE(t_articles.compte_id,0) AS compte_id,
|
|
|
COALESCE(t_ucd.oid,0) AS ucd_id,
|
|
|
COALESCE(t_lpp.oid,t_lpp_prod.oid,0) AS lpp_id,
|
|
|
COALESCE(t_unites_fonctionnelles.oid,0) AS unite_fonctionnelle_id,
|
|
|
COALESCE(t_fournisseurs.oid,t_fournisseurs_articles.oid,0) AS fournisseur_id,
|
|
|
COALESCE(p_commandes.oid,0) AS commande_id,
|
|
|
LIGNE.NOLIGCMDE AS ligne_commande,
|
|
|
base.cti_division(VALTTC::numeric , QUANTITE::numeric) AS prix_unitaire,
|
|
|
CASE WHEN SENSMVT = '1' THEN QUANTITE::numeric ELSE 0 END AS entree_quantite,
|
|
|
CASE WHEN SENSMVT <> '1' THEN QUANTITE::numeric ELSE 0 END AS sortie_quantite,
|
|
|
CASE WHEN SENSMVT = '1' THEN VALTTC::numeric ELSE 0 END AS entree_montant,
|
|
|
CASE WHEN SENSMVT <> '1' THEN VALTTC::numeric ELSE 0 END AS sortie_montant,
|
|
|
CASE WHEN SENSMVT = '1' THEN VALHT::numeric ELSE 0 END AS entree_montant_ht,
|
|
|
CASE WHEN SENSMVT <> '1' THEN VALHT::numeric ELSE 0 END AS sortie_montant_ht,
|
|
|
CASE WHEN SENSMVT <> '1' THEN VALTTC::numeric ELSE 0 END AS sortie_montant_original_ttc,
|
|
|
CASE WHEN SENSMVT <> '1' THEN VALHT::numeric ELSE 0 END AS sortie_montant_original_ht,
|
|
|
0 AS stock_quantite_debut,
|
|
|
0 AS stock_quantite_fin,
|
|
|
CASE WHEN t_articles.type_prorata_tva IS DISTINCT FROM '1' THEN COALESCE(t_prorata_tva.taux,0) ELSE 0 END,
|
|
|
w_MVTPDT.no_patient,
|
|
|
w_MVTPDT.no_sejour
|
|
|
FROM w_MVTPDT
|
|
|
LEFT JOIN prod_pharma.MAGASIN ON MAGASIN = CODEMAGASIN
|
|
|
LEFT JOIN prod_pharma.PRODUIT ON PRODUIT.PRCLEUNIK = w_MVTPDT.PRCLEUNIK
|
|
|
LEFT JOIN eco.t_types_mouvements ON to_char(TYPEMVT,'FM00') || '|' || TYPESORTIE = t_types_mouvements.code_original
|
|
|
LEFT JOIN eco.t_gestionnaires ON '0' = t_gestionnaires.code_original
|
|
|
LEFT JOIN eco.t_divers ON t_divers.code = 'PHARMA_MAG_LIEU'
|
|
|
LEFT JOIN eco.t_sites ON CASE WHEN t_divers.valeur = '0' THEN COALESCE (MAGASIN::text,'0') ELSE '0' END = t_sites.code
|
|
|
LEFT JOIN eco.t_lieux ON CASE WHEN t_divers.valeur = '0'::text THEN LIEUSTOCK::text ELSE IDMAGASIN::text END = t_lieux.code_original
|
|
|
LEFT JOIN eco.t_profils_comptables ON profil_code_original = t_profils_comptables.code_original
|
|
|
LEFT JOIN eco.t_articles ON w_MVTPDT.PRCLEUNIK = t_articles.code_original
|
|
|
LEFT JOIN eco.t_fournisseurs ON w_MVTPDT.F0CLEUNIK = t_fournisseurs.code_original AND w_MVTPDT.F0CLEUNIK > 1
|
|
|
LEFT JOIN eco.t_fournisseurs t_fournisseurs_articles ON PRODUIT.F0CLEUNIK = t_fournisseurs_articles.code_original AND PRODUIT.F0CLEUNIK > 1
|
|
|
LEFT JOIN w_LIGNE_source LIGNE ON w_MVTPDT.L0CLEUNIK = LIGNE.L0CLEUNIK
|
|
|
LEFT JOIN eco.p_commandes ON w_MVTPDT.C1CLEUNIK = p_commandes.code_original
|
|
|
LEFT JOIN base.t_ucd ON w_MVTPDT.CODE_UCD = t_ucd.code
|
|
|
LEFT JOIN base.t_lpp ON w_MVTPDT.CODE_LPP = t_lpp.code
|
|
|
LEFT JOIN base.t_lpp t_lpp_prod ON PRODUIT.CODELPP = t_lpp_prod.code
|
|
|
LEFT JOIN eco.t_unites_fonctionnelles ON w_MVTPDT.SERVICE = t_unites_fonctionnelles.code_original AND w_MVTPDT.SERVICE <> '-1'
|
|
|
LEFT JOIN eco.t_prorata_tva ON t_prorata_tva.oid = 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');
|
|
|
|
|
|
|
|
|
|
|
|
]]></sqlcmd>
|
|
|
</NODE>
|
|
|
|
|
|
|
|
|
<NODE label="Factures">
|
|
|
<sqlcmd><![CDATA[
|
|
|
|
|
|
DROP TABLE IF EXISTS w_ACHATS_0;
|
|
|
CREATE TEMP TABLE w_ACHATS_0 AS
|
|
|
SELECT
|
|
|
DATEFACT,
|
|
|
REFCMDE,
|
|
|
F0CLEUNIK,
|
|
|
COMPTE,
|
|
|
SUM(MONTANT),
|
|
|
base.cti_group_array3(ACCLEUNIK) AS ACCLEUNIK_array
|
|
|
FROM prod_pharma.ACHATS
|
|
|
WHERE REFFACT <> ''
|
|
|
GROUP BY 1,2,3,4
|
|
|
HAVING round(SUM(MONTANT)::numeric,2) = 0;
|
|
|
|
|
|
ANALYSE w_ACHATS_0
|
|
|
;
|
|
|
|
|
|
DROP TABLE IF EXISTS w_ACHATS;
|
|
|
CREATE TEMP TABLE w_ACHATS AS
|
|
|
SELECT ACHATS.*,
|
|
|
COALESCE(to_char(ACHATS.DATEFACT,'YYYYMMDD'),'00000000')||'_'||ACHATS.REFFACT||'_'||ACHATS.F0CLEUNIK AS code_original_facture,
|
|
|
CASE WHEN MONTANT >= 0 THEN 1 ELSE -1 END AS SENS,
|
|
|
COALESCE(C1CLEUNIK,0) AS C1CLEUNIK,
|
|
|
NULL::numeric[] AS L0CLEUNIK_array,
|
|
|
'0'::text AS commande_ok,
|
|
|
'0'::text AS ligne_ok
|
|
|
FROM prod_pharma.ACHATS
|
|
|
LEFT JOIN w_COMMANDE ON LPAD(to_char(NUMCMDE,'FM0000000') || SUFCMDE,10,'0') = LPAD(trim(REFCMDE),10,'0') AND
|
|
|
w_COMMANDE.F0CLEUNIK = ACHATS.F0CLEUNIK AND
|
|
|
NUMCMDE <> 0
|
|
|
LEFT JOIN w_ACHATS_0 ON
|
|
|
ACHATS.REFCMDE = w_ACHATS_0.REFCMDE AND
|
|
|
ACCLEUNIK = ANY (ACCLEUNIK_array)
|
|
|
WHERE ACHATS.REFFACT <> '' AND w_ACHATS_0.DATEFACT IS NULL AND ACHATS.MONTANT <> 0;
|
|
|
|
|
|
UPDATE w_ACHATS
|
|
|
SET NOLIQUIDAT = subview.NOLIQUIDAT
|
|
|
FROM
|
|
|
(SELECT REFCMDE, MAX(NOLIQUIDAT) AS NOLIQUIDAT
|
|
|
FROM w_ACHATS
|
|
|
WHERE NOLIQUIDAT <> '1'
|
|
|
GROUP BY 1
|
|
|
HAVING count(DISTINCT NOLIQUIDAT) = 1
|
|
|
) subview
|
|
|
WHERE w_ACHATS.REFCMDE = subview.REFCMDE AND w_ACHATS.NOLIQUIDAT = '1';
|
|
|
|
|
|
|
|
|
UPDATE w_ACHATS
|
|
|
SET NOLIQUIDAT = (SELECT (MAX(Array[DATEFACT::text,NOLIQUIDAT::text]))[2]::numeric FROM w_ACHATS w_ACHATS_p WHERE w_ACHATS_p.REFCMDE = w_ACHATS.REFCMDE AND
|
|
|
w_ACHATS.MONTANT = 0 - w_ACHATS_p.MONTANT AND
|
|
|
w_ACHATS_p.NOLIQUIDAT <> '1' AND
|
|
|
(w_ACHATS_p.ACCLEUNIK < w_ACHATS.ACCLEUNIK)
|
|
|
)
|
|
|
WHERE NOLIQUIDAT = 1 AND
|
|
|
(SELECT MAX(Array[DATEFACT::text,NOLIQUIDAT::text]) FROM w_ACHATS w_ACHATS_p WHERE w_ACHATS_p.REFCMDE = w_ACHATS.REFCMDE AND
|
|
|
w_ACHATS.MONTANT = 0 - w_ACHATS_p.MONTANT AND
|
|
|
w_ACHATS_p.NOLIQUIDAT <> '1' AND
|
|
|
(w_ACHATS_p.ACCLEUNIK < w_ACHATS.ACCLEUNIK)
|
|
|
) IS NOT NULL;
|
|
|
|
|
|
|
|
|
UPDATE w_ACHATS
|
|
|
SET NOLIQUIDAT = (SELECT (MAX(Array[DATEFACT::text,NOLIQUIDAT::text]))[2]::numeric FROM w_ACHATS w_ACHATS_p WHERE w_ACHATS_p.REFCMDE = w_ACHATS.REFCMDE AND
|
|
|
w_ACHATS.MONTANT = 0 - w_ACHATS_p.MONTANT AND
|
|
|
w_ACHATS_p.NOLIQUIDAT <> '1' AND
|
|
|
(w_ACHATS_p.DATEFACT < w_ACHATS.DATEFACT OR
|
|
|
w_ACHATS_p.DATEFACT = w_ACHATS.DATEFACT AND w_ACHATS_p.DATESAISIE < w_ACHATS.DATESAISIE OR
|
|
|
w_ACHATS_p.DATEFACT = w_ACHATS.DATEFACT AND w_ACHATS_p.DATESAISIE = w_ACHATS.DATESAISIE AND w_ACHATS_p.ACCLEUNIK < w_ACHATS.ACCLEUNIK)
|
|
|
)
|
|
|
WHERE NOLIQUIDAT = 1 AND
|
|
|
(SELECT MAX(Array[DATEFACT::text,NOLIQUIDAT::text]) FROM w_ACHATS w_ACHATS_p WHERE w_ACHATS_p.REFCMDE = w_ACHATS.REFCMDE AND
|
|
|
w_ACHATS.MONTANT = 0 - w_ACHATS_p.MONTANT AND
|
|
|
w_ACHATS_p.NOLIQUIDAT <> '1' AND
|
|
|
(w_ACHATS_p.DATEFACT < w_ACHATS.DATEFACT OR
|
|
|
w_ACHATS_p.DATEFACT = w_ACHATS.DATEFACT AND w_ACHATS_p.DATESAISIE < w_ACHATS.DATESAISIE OR
|
|
|
w_ACHATS_p.DATEFACT = w_ACHATS.DATEFACT AND w_ACHATS_p.DATESAISIE = w_ACHATS.DATESAISIE AND w_ACHATS_p.ACCLEUNIK < w_ACHATS.ACCLEUNIK)
|
|
|
) IS NOT NULL;
|
|
|
|
|
|
|
|
|
|
|
|
DROP TABLE IF EXISTS w_ACHATS_0;
|
|
|
CREATE TEMP TABLE w_ACHATS_0 AS
|
|
|
SELECT
|
|
|
DATEFACT,
|
|
|
REFCMDE,
|
|
|
F0CLEUNIK,
|
|
|
NOLIQUIDAT,
|
|
|
COMPTE,
|
|
|
SUM(MONTANT),
|
|
|
base.cti_group_array3(ACCLEUNIK) AS ACCLEUNIK_array
|
|
|
FROM w_ACHATS
|
|
|
GROUP BY 1,2,3,4,5
|
|
|
HAVING round(SUM(MONTANT)::numeric,2) = 0;
|
|
|
|
|
|
DELETE FROM w_ACHATS
|
|
|
USING
|
|
|
w_ACHATS_0
|
|
|
WHERE w_ACHATS.REFCMDE = w_ACHATS_0.REFCMDE AND
|
|
|
ACCLEUNIK = ANY (ACCLEUNIK_array);
|
|
|
|
|
|
-- correction date facture nulle
|
|
|
|
|
|
UPDATE w_ACHATS
|
|
|
SET DATEFACT = subview.DATEFACT,
|
|
|
code_original_facture = COALESCE(to_char(subview.DATEFACT,'YYYYMMDD'),'00000000')||'_'||w_ACHATS.REFFACT||'_'||w_ACHATS.F0CLEUNIK
|
|
|
FROM
|
|
|
(
|
|
|
SELECT w_ACHATS.ACCLEUNIK AS ACCLEUNIK, (MAX(Array[w_ACHATS_2.ACCLEUNIK::text,w_ACHATS_2.DATEFACT::text]))[2]::date AS DATEFACT
|
|
|
FROM w_ACHATS
|
|
|
JOIN w_ACHATS w_ACHATS_2
|
|
|
ON w_ACHATS.REFCMDE = w_ACHATS_2.REFCMDE AND
|
|
|
w_ACHATS.COMPTE = w_ACHATS_2.COMPTE AND
|
|
|
w_ACHATS.NOLIQUIDAT = w_ACHATS_2.NOLIQUIDAT AND
|
|
|
w_ACHATS.REFMARCHE = w_ACHATS_2.REFMARCHE AND
|
|
|
w_ACHATS.C1CLEUNIK = w_ACHATS_2.C1CLEUNIK AND
|
|
|
w_ACHATS.ACCLEUNIK < w_ACHATS_2.ACCLEUNIK AND
|
|
|
w_ACHATS.DATEFACT IS NULL AND
|
|
|
w_ACHATS_2.DATEFACT IS NOT NULL
|
|
|
GROUP BY 1
|
|
|
) subview
|
|
|
WHERE w_ACHATS.ACCLEUNIK = subview.ACCLEUNIK;
|
|
|
|
|
|
|
|
|
-- Suppression des annulations
|
|
|
|
|
|
|
|
|
DELETE FROM w_ACHATS
|
|
|
USING (
|
|
|
SELECT w_ACHATS.ACCLEUNIK AS ACCLEUNIK_ANN, MAX(w_ACHATS_2.ACCLEUNIK) AS ACCLEUNIK
|
|
|
FROM w_ACHATS
|
|
|
JOIN w_ACHATS w_ACHATS_2
|
|
|
ON w_ACHATS.DATEFACT = w_ACHATS_2.DATEFACT AND
|
|
|
w_ACHATS.REFCMDE = w_ACHATS_2.REFCMDE AND
|
|
|
w_ACHATS.COMPTE = w_ACHATS_2.COMPTE AND
|
|
|
w_ACHATS.NOLIQUIDAT = w_ACHATS_2.NOLIQUIDAT AND
|
|
|
w_ACHATS.REFMARCHE = w_ACHATS_2.REFMARCHE AND
|
|
|
w_ACHATS.C1CLEUNIK = w_ACHATS_2.C1CLEUNIK AND
|
|
|
w_ACHATS.MONTANT < 0 AND
|
|
|
w_ACHATS.ACCLEUNIK > w_ACHATS_2.ACCLEUNIK AND
|
|
|
round(w_ACHATS.MONTANT::numeric,2) = 0- round(w_ACHATS_2.MONTANT::numeric,2)
|
|
|
GROUP BY 1
|
|
|
) subview
|
|
|
WHERE w_ACHATS.ACCLEUNIK = subview.ACCLEUNIK_ANN OR
|
|
|
w_ACHATS.ACCLEUNIK = subview.ACCLEUNIK;
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
UPDATE w_ACHATS
|
|
|
SET commande_ok = '1'
|
|
|
FROM
|
|
|
(SELECT
|
|
|
REFCMDE,
|
|
|
w_ACHATS.C1CLEUNIK,
|
|
|
NOLIQUIDAT,
|
|
|
TOTFACTTTC,
|
|
|
SUM(MONTANT) AS montant
|
|
|
FROM w_ACHATS
|
|
|
JOIN w_COMMANDE ON w_COMMANDE.C1CLEUNIK = w_ACHATS.C1CLEUNIK AND NOLIQUID = NOLIQUIDAT
|
|
|
GROUP BY 1,2,3,4
|
|
|
HAVING round(TOTFACTTTC::numeric,2) = round(SUM(MONTANT)::numeric,2)
|
|
|
) subview
|
|
|
WHERE subview.REFCMDE = w_ACHATS.REFCMDE AND subview.NOLIQUIDAT = w_ACHATS.NOLIQUIDAT;
|
|
|
|
|
|
|
|
|
UPDATE w_ACHATS
|
|
|
SET commande_ok = '2'
|
|
|
FROM
|
|
|
(SELECT
|
|
|
REFCMDE,
|
|
|
w_ACHATS.C1CLEUNIK,
|
|
|
NOLIQUIDAT,
|
|
|
TOTFACTTTC,
|
|
|
SUM(MONTANT) AS montant
|
|
|
FROM w_ACHATS
|
|
|
JOIN w_COMMANDE ON w_COMMANDE.C1CLEUNIK = w_ACHATS.C1CLEUNIK
|
|
|
GROUP BY 1,2,3,4
|
|
|
HAVING round(TOTFACTTTC::numeric,2) = round(SUM(MONTANT)::numeric,2)
|
|
|
) subview
|
|
|
WHERE commande_ok = '0' AND subview.REFCMDE = w_ACHATS.REFCMDE AND subview.NOLIQUIDAT = w_ACHATS.NOLIQUIDAT;
|
|
|
|
|
|
|
|
|
UPDATE w_ACHATS
|
|
|
SET commande_ok = '3'
|
|
|
FROM
|
|
|
(SELECT
|
|
|
REFCMDE,
|
|
|
w_ACHATS.C1CLEUNIK,
|
|
|
TOTFACTTTC,
|
|
|
SUM(MONTANT) AS montant
|
|
|
FROM w_ACHATS
|
|
|
JOIN w_COMMANDE ON w_COMMANDE.C1CLEUNIK = w_ACHATS.C1CLEUNIK
|
|
|
GROUP BY 1,2,3
|
|
|
HAVING round(TOTFACTTTC::numeric,2) = round(SUM(MONTANT)::numeric,2)
|
|
|
) subview
|
|
|
WHERE commande_ok = '0' AND subview.REFCMDE = w_ACHATS.REFCMDE;
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
DROP TABLE IF EXISTS w_LIGNE;
|
|
|
CREATE TEMP TABLE w_LIGNE AS
|
|
|
SELECT C1CLEUNIK, COMPTE.COMPTE, NUMMARCHE, round(SUM(FACTTTC)::numeric,2) AS FACTTTC , round(SUM(VALEURTTC)::numeric,2) AS VALEURTTC, base.cti_group_array3(L0CLEUNIK) AS L0CLEUNIK_array
|
|
|
FROM w_LIGNE_source LIGNE
|
|
|
JOIN prod_pharma.PRODUIT ON ligne.PRCLEUNIK = PRODUIT.PRCLEUNIK
|
|
|
JOIN prod_pharma.COMPTE ON PRODUIT.COMPTE = COMPTE.COMPTE
|
|
|
GROUP BY 1,2,3;
|
|
|
|
|
|
|
|
|
UPDATE w_ACHATS
|
|
|
SET L0CLEUNIK_array = w_LIGNE.L0CLEUNIK_array, ligne_ok = '1'
|
|
|
FROM w_LIGNE
|
|
|
WHERE w_ACHATS.L0CLEUNIK_array IS NULL AND
|
|
|
w_ACHATS.C1CLEUNIK = w_LIGNE.C1CLEUNIK AND
|
|
|
w_ACHATS.REFMARCHE = w_LIGNE.NUMMARCHE AND
|
|
|
w_ACHATS.COMPTE = w_LIGNE.COMPTE AND
|
|
|
MONTANT - VALEURTTC BETWEEN -0.01 AND 0.01;
|
|
|
|
|
|
|
|
|
|
|
|
DROP TABLE IF EXISTS w_LIGNE;
|
|
|
CREATE TEMP TABLE w_LIGNE AS
|
|
|
SELECT C1CLEUNIK, COMPTEPDT, NUMMARCHE, round(SUM(FACTTTC)::numeric,2) AS FACTTTC , round(SUM(VALEURTTC)::numeric,2) AS VALEURTTC, base.cti_group_array3(L0CLEUNIK) AS L0CLEUNIK_array
|
|
|
FROM w_LIGNE_source LIGNE
|
|
|
GROUP BY 1,2,3;
|
|
|
|
|
|
|
|
|
UPDATE w_ACHATS
|
|
|
SET L0CLEUNIK_array = w_LIGNE.L0CLEUNIK_array, ligne_ok = '2'
|
|
|
FROM w_LIGNE
|
|
|
WHERE w_ACHATS.L0CLEUNIK_array IS NULL AND
|
|
|
w_ACHATS.C1CLEUNIK = w_LIGNE.C1CLEUNIK AND
|
|
|
w_ACHATS.REFMARCHE = w_LIGNE.NUMMARCHE AND
|
|
|
w_ACHATS.COMPTE = w_LIGNE.COMPTEPDT AND
|
|
|
MONTANT - VALEURTTC BETWEEN -0.01 AND 0.01;
|
|
|
|
|
|
|
|
|
UPDATE w_ACHATS
|
|
|
SET L0CLEUNIK_array = Array[LIGNE.L0CLEUNIK], ligne_ok = '3'
|
|
|
FROM w_LIGNE_source LIGNE
|
|
|
JOIN prod_pharma.PRODUIT ON ligne.PRCLEUNIK = PRODUIT.PRCLEUNIK
|
|
|
JOIN prod_pharma.COMPTE ON PRODUIT.COMPTE = COMPTE.COMPTE
|
|
|
WHERE w_ACHATS.L0CLEUNIK_array IS NULL AND
|
|
|
w_ACHATS.C1CLEUNIK = LIGNE.C1CLEUNIK AND
|
|
|
w_ACHATS.REFMARCHE = LIGNE.NUMMARCHE AND
|
|
|
w_ACHATS.COMPTE = PRODUIT.COMPTE AND
|
|
|
MONTANT - VALEURTTC BETWEEN -0.01 AND 0.01;
|
|
|
|
|
|
|
|
|
|
|
|
UPDATE w_ACHATS
|
|
|
SET L0CLEUNIK_array = Array[LIGNE.L0CLEUNIK], ligne_ok = '4'
|
|
|
FROM w_LIGNE_source LIGNE
|
|
|
WHERE L0CLEUNIK_array IS NULL AND
|
|
|
w_ACHATS.C1CLEUNIK = LIGNE.C1CLEUNIK AND
|
|
|
w_ACHATS.REFMARCHE = LIGNE.NUMMARCHE AND
|
|
|
w_ACHATS.COMPTE = LIGNE.COMPTEPDT AND
|
|
|
MONTANT - VALEURTTC BETWEEN -0.01 AND 0.01;
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
DROP TABLE IF EXISTS w_LIGNE;
|
|
|
CREATE TEMP TABLE w_LIGNE AS
|
|
|
SELECT LIGNE.C1CLEUNIK, COMPTE.COMPTE, NUMMARCHE, round(SUM(FACTTTC)::numeric,2) AS FACTTTC , round(SUM(VALEURTTC)::numeric,2) AS VALEURTTC, base.cti_group_array3(L0CLEUNIK) AS L0CLEUNIK_array
|
|
|
FROM w_LIGNE_source LIGNE
|
|
|
LEFT JOIN w_ACHATS ON LIGNE.C1CLEUNIK = w_ACHATS.C1CLEUNIK AND LIGNE.L0CLEUNIK = ANY (L0CLEUNIK_array)
|
|
|
JOIN prod_pharma.PRODUIT ON ligne.PRCLEUNIK = PRODUIT.PRCLEUNIK
|
|
|
JOIN prod_pharma.COMPTE ON PRODUIT.COMPTE = COMPTE.COMPTE
|
|
|
WHERE w_ACHATS.C1CLEUNIK IS NULL
|
|
|
GROUP BY 1,2,3;
|
|
|
|
|
|
|
|
|
UPDATE w_ACHATS
|
|
|
SET L0CLEUNIK_array = w_LIGNE.L0CLEUNIK_array, ligne_ok = '5'
|
|
|
FROM w_LIGNE
|
|
|
WHERE w_ACHATS.L0CLEUNIK_array IS NULL AND
|
|
|
w_ACHATS.C1CLEUNIK = w_LIGNE.C1CLEUNIK AND
|
|
|
w_ACHATS.REFMARCHE = w_LIGNE.NUMMARCHE AND
|
|
|
w_ACHATS.COMPTE = w_LIGNE.COMPTE AND
|
|
|
(round(MONTANT::numeric,2) = VALEURTTC OR round(MONTANT::numeric,2) = 0 - VALEURTTC);
|
|
|
|
|
|
|
|
|
DROP TABLE IF EXISTS w_LIGNE;
|
|
|
CREATE TEMP TABLE w_LIGNE AS
|
|
|
SELECT LIGNE.C1CLEUNIK, COMPTEPDT, NUMMARCHE, round(SUM(FACTTTC)::numeric,2) AS FACTTTC , round(SUM(VALEURTTC)::numeric,2) AS VALEURTTC, base.cti_group_array3(L0CLEUNIK) AS L0CLEUNIK_array
|
|
|
FROM w_LIGNE_source LIGNE
|
|
|
LEFT JOIN w_ACHATS ON LIGNE.C1CLEUNIK = w_ACHATS.C1CLEUNIK AND LIGNE.L0CLEUNIK = ANY (L0CLEUNIK_array)
|
|
|
WHERE w_ACHATS.C1CLEUNIK IS NULL
|
|
|
GROUP BY 1,2,3;
|
|
|
|
|
|
|
|
|
UPDATE w_ACHATS
|
|
|
SET L0CLEUNIK_array = w_LIGNE.L0CLEUNIK_array, ligne_ok = '6'
|
|
|
FROM w_LIGNE
|
|
|
WHERE w_ACHATS.L0CLEUNIK_array IS NULL AND
|
|
|
w_ACHATS.C1CLEUNIK = w_LIGNE.C1CLEUNIK AND
|
|
|
w_ACHATS.REFMARCHE = w_LIGNE.NUMMARCHE AND
|
|
|
w_ACHATS.COMPTE = w_LIGNE.COMPTEPDT AND
|
|
|
(round(MONTANT::numeric,2) = VALEURTTC OR round(MONTANT::numeric,2) = 0 - VALEURTTC);
|
|
|
|
|
|
|
|
|
|
|
|
DROP TABLE IF EXISTS w_LIGNE;
|
|
|
CREATE TEMP TABLE w_LIGNE AS
|
|
|
SELECT LIGNE.C1CLEUNIK, COMPTE.COMPTE, NUMMARCHE, round(SUM(FACTTTC)::numeric,2) AS FACTTTC , round(SUM(VALEURTTC)::numeric,2) AS VALEURTTC, base.cti_group_array3(L0CLEUNIK) AS L0CLEUNIK_array
|
|
|
FROM w_LIGNE_source LIGNE
|
|
|
LEFT JOIN w_ACHATS ON LIGNE.C1CLEUNIK = w_ACHATS.C1CLEUNIK AND LIGNE.L0CLEUNIK = ANY (L0CLEUNIK_array)
|
|
|
JOIN prod_pharma.PRODUIT ON ligne.PRCLEUNIK = PRODUIT.PRCLEUNIK
|
|
|
JOIN prod_pharma.COMPTE ON PRODUIT.COMPTE = COMPTE.COMPTE
|
|
|
WHERE w_ACHATS.C1CLEUNIK IS NULL
|
|
|
GROUP BY 1,2,3;
|
|
|
|
|
|
|
|
|
UPDATE w_ACHATS
|
|
|
SET L0CLEUNIK_array = w_LIGNE.L0CLEUNIK_array, ligne_ok = '7'
|
|
|
FROM w_LIGNE
|
|
|
WHERE w_ACHATS.L0CLEUNIK_array IS NULL AND
|
|
|
w_ACHATS.C1CLEUNIK = w_LIGNE.C1CLEUNIK AND
|
|
|
w_ACHATS.COMPTE = w_LIGNE.COMPTE AND
|
|
|
w_ACHATS.REFMARCHE = w_LIGNE.NUMMARCHE AND
|
|
|
(round(MONTANT::numeric,2) = VALEURTTC OR round(MONTANT::numeric,2) = 0 - VALEURTTC);
|
|
|
|
|
|
|
|
|
DROP TABLE IF EXISTS w_LIGNE;
|
|
|
CREATE TEMP TABLE w_LIGNE AS
|
|
|
SELECT LIGNE.C1CLEUNIK, COMPTEPDT, NUMMARCHE, round(SUM(FACTTTC)::numeric,2) AS FACTTTC , round(SUM(VALEURTTC)::numeric,2) AS VALEURTTC, base.cti_group_array3(L0CLEUNIK) AS L0CLEUNIK_array
|
|
|
FROM w_LIGNE_source LIGNE
|
|
|
LEFT JOIN w_ACHATS ON LIGNE.C1CLEUNIK = w_ACHATS.C1CLEUNIK AND LIGNE.L0CLEUNIK = ANY (L0CLEUNIK_array)
|
|
|
WHERE w_ACHATS.C1CLEUNIK IS NULL
|
|
|
GROUP BY 1,2,3;
|
|
|
|
|
|
|
|
|
|
|
|
UPDATE w_ACHATS
|
|
|
SET L0CLEUNIK_array = w_LIGNE.L0CLEUNIK_array, ligne_ok = '8'
|
|
|
FROM w_LIGNE
|
|
|
WHERE w_ACHATS.L0CLEUNIK_array IS NULL AND
|
|
|
w_ACHATS.C1CLEUNIK = w_LIGNE.C1CLEUNIK AND
|
|
|
w_ACHATS.COMPTE = w_LIGNE.COMPTEPDT AND
|
|
|
w_ACHATS.REFMARCHE = w_LIGNE.NUMMARCHE AND
|
|
|
(round(MONTANT::numeric,2) = VALEURTTC OR round(MONTANT::numeric,2) = 0 - VALEURTTC);
|
|
|
|
|
|
|
|
|
DROP TABLE IF EXISTS w_LIGNE;
|
|
|
CREATE TEMP TABLE w_LIGNE AS
|
|
|
SELECT LIGNE.C1CLEUNIK, round(SUM(FACTTTC)::numeric,2) AS FACTTTC , round(SUM(VALEURTTC)::numeric,2) AS VALEURTTC, base.cti_group_array3(L0CLEUNIK) AS L0CLEUNIK_array
|
|
|
FROM w_LIGNE_source LIGNE
|
|
|
GROUP BY 1
|
|
|
HAVING count(*) = 1;
|
|
|
|
|
|
|
|
|
UPDATE w_ACHATS
|
|
|
SET L0CLEUNIK_array = w_LIGNE.L0CLEUNIK_array, ligne_ok = '9'
|
|
|
FROM w_LIGNE
|
|
|
WHERE w_ACHATS.L0CLEUNIK_array IS NULL AND
|
|
|
w_ACHATS.C1CLEUNIK = w_LIGNE.C1CLEUNIK AND
|
|
|
(round(MONTANT::numeric,2) = VALEURTTC OR round(MONTANT::numeric,2) = 0 - VALEURTTC);
|
|
|
|
|
|
|
|
|
|
|
|
INSERT INTO eco.p_commandes(
|
|
|
numero,
|
|
|
date_commande,
|
|
|
objet,
|
|
|
reference,
|
|
|
date_livraison_prevue,
|
|
|
etat_reception,
|
|
|
date_reception,
|
|
|
fournisseur_id,
|
|
|
gestionnaire_id,
|
|
|
lieu_facturation_id,
|
|
|
lieu_livraison_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,
|
|
|
etat_liquidation,
|
|
|
code_original,
|
|
|
unite_fonctionnelle_id,
|
|
|
lieu_commande_id)
|
|
|
SELECT
|
|
|
REFCMDE AS numero,
|
|
|
DATESAISIE AS date_commande,
|
|
|
'Achat sans commande' AS objet,
|
|
|
CASE WHEN REFFACT <> '' THEN 'REFFACT:' || REFFACT ELSE 'SANS N°FACTURE' END AS reference,
|
|
|
COALESCE(DATELIV,'20991231') AS date_livraison_prevue,
|
|
|
'0' AS etat_reception,
|
|
|
DATESAISIE AS date_reception,
|
|
|
COALESCE(t_fournisseurs.oid,0) AS fournisseur_id,
|
|
|
0 AS gestionnaire_id,
|
|
|
0 AS lieu_facturation_id,
|
|
|
0 AS lieu_livraison_id,
|
|
|
0 AS montant_commande_ht,
|
|
|
0 AS montant_commande_remise,
|
|
|
0 AS montant_commande_tva,
|
|
|
0 AS montant_commande_port,
|
|
|
0 AS montant_commande_total,
|
|
|
0 AS montant_liquidation_ht,
|
|
|
0 AS montant_liquidation_remise,
|
|
|
0 AS montant_liquidation_tva,
|
|
|
0 AS montant_liquidation_port,
|
|
|
MONTANT::numeric(15,2) AS montant_liquidation_total,
|
|
|
'0' AS etat_liquidation,
|
|
|
(0-ACCLEUNIK) AS code_original,
|
|
|
0 AS unite_fonctionnelle_id,
|
|
|
0 AS lieu_commande_id
|
|
|
FROM w_ACHATS
|
|
|
LEFT JOIN eco.t_fournisseurs ON w_ACHATS.F0CLEUNIK = t_fournisseurs.code_original
|
|
|
WHERE C1CLEUNIK = 0 AND DATEFACT >= '[ENV_ECO_ANNEEDEBUT]0101' AND
|
|
|
(0-ACCLEUNIK) NOT IN (SELECT code_original FROM eco.p_commandes)
|
|
|
;
|
|
|
|
|
|
UPDATE w_ACHATS
|
|
|
SET C1CLEUNIK = 0-ACCLEUNIK
|
|
|
FROM eco.p_commandes
|
|
|
WHERE w_ACHATS.C1CLEUNIK = 0 AND 0-ACCLEUNIK = code_original;
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
TRUNCATE eco.p_facture;
|
|
|
|
|
|
INSERT INTO eco.p_facture(
|
|
|
code_original,
|
|
|
no_facture,
|
|
|
date_facture,
|
|
|
texte,
|
|
|
fournisseur_id,
|
|
|
commande_id,
|
|
|
no_liquidation,
|
|
|
montant_facture_ht,
|
|
|
montant_facture_tva,
|
|
|
montant_facture_ttc,
|
|
|
montant_facture_article_ht,
|
|
|
montant_facture_article_tva,
|
|
|
montant_facture_article_ttc,
|
|
|
montant_facture_port_ht,
|
|
|
montant_facture_port_tva,
|
|
|
montant_facture_port_ttc)
|
|
|
SELECT
|
|
|
code_original_facture AS code_original,
|
|
|
w_ACHATS.REFFACT AS no_facture,
|
|
|
DATEFACT AS date_facture,
|
|
|
'Facture n°' || w_ACHATS.REFFACT || CASE WHEN DATEFACT IS NOT NULL THEN ' du ' || to_char(DATEFACT,'DD/MM/YYYY') ELSE ' Sans date' END || ' ' || t_fournisseurs.texte,
|
|
|
COALESCE(t_fournisseurs.oid,0) AS fournisseur_id,
|
|
|
MAX(COALESCE(p_commandes.oid,0)) AS commande_id,
|
|
|
base.cti_group_concat(DISTINCT w_ACHATS.NOLIQUIDAT) AS no_liquidation,
|
|
|
SUM(SENS * COALESCE(LIGNE.VALEURHT,0)::numeric(15,2)) AS montant_facture_ht,
|
|
|
SUM(SENS * COALESCE(LIGNE.VALEURTVA,0)::numeric(15,2)) AS montant_facture_tva,
|
|
|
SUM(SENS * COALESCE(LIGNE.VALEURTTC,MONTANT)::numeric(15,2)) AS montant_facture_ttc,
|
|
|
SUM(SENS * COALESCE(LIGNE.FACTHT,0)::numeric(15,2)) AS montant_facture_article_ht,
|
|
|
SUM(SENS * COALESCE(LIGNE.TOTALTVA,0)::numeric(15,2)) AS montant_facture_article_tva,
|
|
|
SUM(SENS * COALESCE(LIGNE.FACTTTC,0)::numeric(15,2)) AS montant_facture_article_ttc,
|
|
|
SUM(SENS * COALESCE(LIGNE.VALEURHT - LIGNE.FACTHT,0)::numeric(15,2)) AS montant_facture_port_ht,
|
|
|
SUM(SENS * COALESCE(LIGNE.VALEURTVA - LIGNE.TOTALTVA,0)::numeric(15,2)) AS montant_facture_port_tva,
|
|
|
SUM(SENS * COALESCE(LIGNE.VALEURTTC - LIGNE.FACTTTC,0)::numeric(15,2)) AS montant_facture_port_ttc
|
|
|
FROM w_ACHATS
|
|
|
LEFT JOIN w_COMMANDE ON w_ACHATS.C1CLEUNIK = w_COMMANDE.C1CLEUNIK
|
|
|
LEFT JOIN w_LIGNE_source LIGNE ON LIGNE.C1CLEUNIK = w_ACHATS.C1CLEUNIK AND
|
|
|
LIGNE.L0CLEUNIK = ANY (w_ACHATS.L0CLEUNIK_ARRAY)
|
|
|
LEFT JOIN eco.p_commandes ON p_commandes.code_original = w_ACHATS.C1CLEUNIK
|
|
|
LEFT JOIN eco.t_fournisseurs ON w_ACHATS.F0CLEUNIK = t_fournisseurs.code_original
|
|
|
WHERE DATEFACT >= '[ENV_ECO_ANNEEDEBUT]0101' OR p_commandes.oid IS NOT NULL
|
|
|
GROUP BY 1,2,3,4,5;
|
|
|
|
|
|
|
|
|
TRUNCATE eco.p_lignes_facture;
|
|
|
|
|
|
INSERT INTO eco.p_lignes_facture(
|
|
|
code_original,
|
|
|
facture_id,
|
|
|
ligne_commande_id,
|
|
|
article_id,
|
|
|
compte_id,
|
|
|
no_liquidation,
|
|
|
montant_facture_ht,
|
|
|
montant_facture_tva,
|
|
|
montant_facture_ttc,
|
|
|
montant_facture_article_ht,
|
|
|
montant_facture_article_tva,
|
|
|
montant_facture_article_ttc,
|
|
|
montant_facture_port_ht,
|
|
|
montant_facture_port_tva,
|
|
|
montant_facture_port_ttc,
|
|
|
taux_prorata_tva)
|
|
|
SELECT
|
|
|
ACCLEUNIK AS code_original,
|
|
|
COALESCE(p_facture.oid,0) AS facture_id,
|
|
|
COALESCE(p_lignes_commandes.oid,0) AS ligne_commande_id,
|
|
|
COALESCE(t_articles.oid,0) AS article_id,
|
|
|
COALESCE(t_compte.oid,0) AS compte_id,
|
|
|
w_ACHATS.NOLIQUIDAT,
|
|
|
SENS * COALESCE(LIGNE.VALEURHT,0)::numeric(15,2) AS montant_facture_ht,
|
|
|
SENS * COALESCE(LIGNE.VALEURTVA,0)::numeric(15,2) AS montant_facture_tva,
|
|
|
SENS * COALESCE(LIGNE.VALEURTTC,MONTANT)::numeric(15,2) AS montant_facture_ttc,
|
|
|
SENS * COALESCE(LIGNE.FACTHT,0)::numeric(15,2) AS montant_facture_article_ht,
|
|
|
SENS * COALESCE(LIGNE.TOTALTVA,0)::numeric(15,2) AS montant_facture_article_tva,
|
|
|
SENS * COALESCE(LIGNE.FACTTTC,0)::numeric(15,2) AS montant_facture_article_ttc,
|
|
|
SENS * COALESCE(LIGNE.VALEURHT - LIGNE.FACTHT,0)::numeric(15,2) AS montant_facture_port_ht,
|
|
|
SENS * COALESCE(LIGNE.VALEURTVA - LIGNE.TOTALTVA,0)::numeric(15,2) AS montant_facture_port_tva,
|
|
|
SENS * COALESCE(LIGNE.VALEURTTC - LIGNE.FACTTTC,0)::numeric(15,2) AS montant_facture_port_ttc,
|
|
|
CASE WHEN t_articles.type_prorata_tva IS DISTINCT FROM '1' THEN COALESCE(t_prorata_tva.taux,0) ELSE 0 END AS taux_prorata_tva
|
|
|
FROM w_ACHATS
|
|
|
JOIN eco.p_facture ON code_original_facture = p_facture.code_original
|
|
|
LEFT JOIN w_LIGNE_source LIGNE ON LIGNE.C1CLEUNIK = w_ACHATS.C1CLEUNIK AND
|
|
|
LIGNE.L0CLEUNIK = ANY (w_ACHATS.L0CLEUNIK_ARRAY)
|
|
|
LEFT JOIN eco.p_commandes ON p_commandes.code_original = w_ACHATS.C1CLEUNIK
|
|
|
LEFT JOIN eco.p_lignes_commandes ON p_lignes_commandes.code_original = L0CLEUNIK
|
|
|
LEFT JOIN eco.t_articles ON LIGNE.PRCLEUNIK = t_articles.code_original
|
|
|
LEFT JOIN eco.t_compte ON w_ACHATS.COMPTE = t_compte.code_original
|
|
|
LEFT JOIN eco.t_prorata_tva ON t_prorata_tva.oid = 0;
|
|
|
|
|
|
|
|
|
]]></sqlcmd>
|
|
|
</NODE>
|
|
|
</NODE>
|
|
|
<NODE name="POST" label="POST-TRAITEMENTS">
|
|
|
<NODE label="Compléments fournisseurs">
|
|
|
<sqlcmd><![CDATA[
|
|
|
|
|
|
UPDATE eco.t_fournisseurs
|
|
|
SET fournisseur_distributeur_id = subview.fournisseur_distributeur_id
|
|
|
FROM
|
|
|
(
|
|
|
SELECT fournisseur_id, (MAX(Array[nb,fournisseur_distributeur_id]))[2] AS fournisseur_distributeur_id
|
|
|
FROM
|
|
|
(
|
|
|
SELECT fournisseur_id,fournisseur_distributeur_id, count(*) AS nb, max(date_commande)
|
|
|
FROM eco.p_commandes
|
|
|
GROUP BY 1,2
|
|
|
) subview
|
|
|
GROUP BY 1
|
|
|
) subview
|
|
|
WHERE t_fournisseurs.oid = subview.fournisseur_id AND
|
|
|
t_fournisseurs.fournisseur_distributeur_id IS DISTINCT FROM subview.fournisseur_distributeur_id
|
|
|
;
|
|
|
|
|
|
|
|
|
]]></sqlcmd>
|
|
|
</NODE>
|
|
|
|
|
|
<NODE label="Compléments mouvements">
|
|
|
<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();
|
|
|
|
|
|
UPDATE eco.p_stock SET
|
|
|
pump_ttc = pump_mvt
|
|
|
FROM
|
|
|
(SELECT
|
|
|
article_id,
|
|
|
site_id,
|
|
|
date_trunc('month', date) as date_debut,
|
|
|
(MAX(ARRAY[date::text, prix_unitaire_calcule::text]))[2]::numeric as pump_mvt
|
|
|
FROM eco.p_mouvements_articles
|
|
|
JOIN eco.t_divers ON t_divers.code = 'NO_CALC_PUMP' AND t_divers.valeur = '2'
|
|
|
GROUP BY 1,2,3
|
|
|
) sub
|
|
|
WHERE p_stock.article_id = sub.article_id
|
|
|
AND p_stock.site_id = sub.site_id
|
|
|
AND p_stock.date_debut = sub.date_debut
|
|
|
;
|
|
|
|
|
|
SELECT eco.cti_reorganize_sejour();
|
|
|
SELECT eco.cti_reorganize_sejour_ucd_lpp();
|
|
|
]]></sqlcmd>
|
|
|
</NODE>
|
|
|
</NODE>
|
|
|
|
|
|
</ROOT>
|