'' AND F21_REFER <> t_articles.texte THEN ' (' || F21_REFER || ')' ELSE '' END]))[2] AS AFLIFA
FROM prod_cliwin.F_210
JOIN eco.t_articles ON ARCLEUNIK::text = t_articles.code_original
JOIN eco.t_fournisseurs ON F21_IDDIST::text = t_fournisseurs.code_original
WHERE ARCLEUNIK <> 0
GROUP BY 1,2
) subview ON subview.article_id = t_articles.oid
GROUP BY 1,2
ORDER BY 1;
UPDATE eco.t_articles
SET
ref_fournisseur_id = w_articles.ref_fournisseur_id,
ref_fournisseur_texte = w_articles.ref_fournisseur_texte
FROM w_articles
WHERE w_articles.article_id = t_articles.oid AND
(
t_articles.ref_fournisseur_id IS DISTINCT FROM w_articles.ref_fournisseur_id OR
t_articles.ref_fournisseur_texte IS DISTINCT FROM w_articles.ref_fournisseur_texte
);
]]>
'' AND
code_original IS NULL
GROUP BY 1,2,3,4
;
-- Gestionnaires
-- Unités fonctionnelles
DROP TABLE IF EXISTS w_130;
CREATE TEMP TABLE w_130 AS
SELECT F50_DEPT || '-' || F50_SERVI AS F13_code,
MAX(COALESCE(F_130_DEPT.F13_LIBEL1, 'Département ' || F50_DEPT) || ', ' || COALESCE(F_130_SERVI.F13_LIBEL2,'Service ' || F50_SERVI)) AS F13_texte
FROM prod_cliwin.F_500
LEFT JOIN prod_cliwin.F_130 F_130_DEPT ON
F50_DEPT = F_130_DEPT.F13_CODE1 AND COALESCE(F_130_DEPT.F13_CODE2,'') = ''
LEFT JOIN prod_cliwin.F_130 F_130_SERVI ON
F50_DEPT = F_130_SERVI.F13_CODE1 AND F50_SERVI = F_130_SERVI.F13_CODE2
WHERE F50_DEPT <> '' AND F50_DEPT IS NOT NULL
GROUP BY 1
ORDER BY 1;
INSERT INTO eco.t_unites_fonctionnelles(code, texte, texte_court, code_original)
SELECT F13_code,
F13_texte,
substr(F13_texte,1,50),
F13_code
FROM w_130
LEFT JOIN eco.t_unites_fonctionnelles ON code_original = F13_code
WHERE code_original IS NULL
GROUP BY 1,2
ORDER BY 1;
UPDATE eco.t_unites_fonctionnelles SET
texte = F13_texte,
texte_court = substr(F13_texte,1,50)
FROM w_130
WHERE code_original = F13_code AND
(
texte IS DISTINCT FROM F13_texte OR
texte_court IS DISTINCT FROM substr(F13_texte,1,50)
);
-- Site
-- Types mouvements
INSERT INTO eco.t_types_mouvements(code, texte, texte_court, code_original)
SELECT F50_TYPE, F50_TYPE, F50_TYPE, F50_TYPE
FROM prod_cliwin.F_500
LEFT JOIN eco.t_types_mouvements ON (code_original = F50_TYPE)
WHERE F50_TYPE <> '' AND t_types_mouvements.oid IS NULL
GROUP BY 1;
]]>
''
GROUP BY 1,2,3
ORDER BY 1,4,2
) subview;
UPDATE w_210_ucd
SET date_fin = w_210_ucd_2.date_debut - interval '1 day'
FROM w_210_ucd w_210_ucd_2
WHERE w_210_ucd.ARCLEUNIK = w_210_ucd_2.ARCLEUNIK AND
w_210_ucd.sequence = w_210_ucd_2.sequence -1;
DROP SEQUENCE IF EXISTS w_210_fournisseur_sequence;
CREATE TEMP SEQUENCE w_210_fournisseur_sequence;
DROP TABLE IF EXISTS w_210_fournisseur;
CREATE TEMP TABLE w_210_fournisseur AS
SELECT nextval('w_210_fournisseur_sequence'::regclass) AS sequence, *
FROM (
SELECT F_210.ARCLEUNIK,
F21_IDDIST,
t_fournisseurs.oid AS fournisseur_id,
MIN(COALESCE(F50_DATE,'00010101')) AS date_debut,
'20991231'::date AS date_fin
FROM w_210 as F_210
JOIN eco.t_fournisseurs ON F21_IDDIST = t_fournisseurs.code_original
LEFT JOIN prod_cliwin.F_500 ON F_210.ARCLEUNIK = F_500.ARCLEUNIK AND F_210.F21_IDDIST = F_500.FOCLEUNIK AND
F50_TYPE IN ('E', 'R') AND
F_500.FOCLEUNIK <> 0
GROUP BY 1,2,3
ORDER BY 1,4,2
) subview;
UPDATE w_210_fournisseur
SET date_fin = w_210_fournisseur_2.date_debut - interval '1 day'
FROM w_210_fournisseur w_210_fournisseur_2
WHERE w_210_fournisseur.ARCLEUNIK = w_210_fournisseur_2.ARCLEUNIK AND
w_210_fournisseur.sequence = w_210_fournisseur_2.sequence -1;
]]>
= '[ENV_ECO_ANNEEDEBUT]0101';
SELECT base.cti_enable_index('eco', 'i_commandes_1');
SELECT base.cti_enable_index('eco', 'i_commandes_2');
SELECT base.cti_enable_index('eco', 'i_commandes_3');
SELECT base.cti_enable_index('eco', 'i_commandes_4');
SELECT base.cti_enable_index('eco', 'i_commandes_5');
SELECT base.cti_enable_index('eco', 'i_commandes_6');
SELECT base.cti_enable_index('eco', 'i_commandes_7');
SELECT base.cti_enable_index('eco', 'i_commandes_8');
SELECT base.cti_disable_index('eco', 'i_ligne_commandes_1');
SELECT base.cti_disable_index('eco', 'i_ligne_commandes_2');
SELECT base.cti_disable_index('eco', 'i_ligne_commandes_3');
TRUNCATE eco.p_lignes_commandes;
INSERT INTO eco.p_lignes_commandes(
code_original,
commande_id,
ligne_commande,
texte,
article_id,
unite_approvisionnement_id,
compte_id,
ucd_id,
lpp_id,
quantite_approvisionnement,
prix_unitaire_approvisionnement,
multiplicateur_stockage,
quantite_stockage,
prix_unitaire_stockage,
montant_commande_ht,
montant_commande_remise,
montant_commande_tva,
montant_commande_port,
montant_commande_ttc,
quantite_livraison_approvisionnement,
quantite_livraison_stockage,
montant_livraison_ht,
montant_livraison_ttc,
etat_livraison,
montant_liquidation_ht,
montant_liquidation_remise,
montant_liquidation_tva,
montant_liquidation_port,
montant_liquidation_ttc,
etat_liquidation)
SELECT
C2CLEUNIK::text AS code_original,
p_commandes.oid AS commande_id,
0::numeric AS ligne_commande,
F81_LIBEL AS texte,
COALESCE(t_articles.oid, 0) AS article_id,
0::bigint AS unite_approvisionnement_id,
COALESCE(t_compte.oid, t_articles.compte_id, 0) AS compte_id,
COALESCE(t_ucd.oid, t_articles.ucd_id, 0) AS ucd_id,
COALESCE(t_lpp.oid, t_articles.lpp_id, 0) AS lpp_id,
F81_QTECOM * CASE WHEN F80_TOTHT >= 0 THEN 1 ELSE -1 END AS quantite_approvisionnement,
F81_PRICOM AS prix_unitaire_approvisionnement,
0::numeric AS multiplicateur_stockage,
0::numeric AS quantite_stockage,
0::numeric AS prix_unitaire_stockage,
(F81_PRICOM * F81_QTECOM) * CASE WHEN F80_TOTHT >= 0 THEN 1 ELSE -1 END AS montant_commande_ht,
(round(F81_PRICOM * (F81_TXTVAI/100),5) * F81_QTECOM) * CASE WHEN F80_TOTHT >= 0 THEN 1 ELSE -1 END::numeric AS montant_commande_remise,
round(F81_PRICOM * (1 - F81_TXTVAI/100),5) * F81_QTECOM * COALESCE(w_TVA.taux,0) * CASE WHEN F80_TOTHT >= 0 THEN 1 ELSE -1 END AS montant_commande_tva,
0::numeric AS montant_commande_port,
round(F81_PRICOM * (1 - F81_TXTVAI/100),5) * F81_QTECOM + round(F81_PRICOM * (1 - F81_TXTVAI/100),5) * F81_QTECOM * COALESCE(w_TVA.taux,0) * CASE WHEN F80_TOTHT >= 0 THEN 1 ELSE -1 END AS montant_commande_ttc,
F81_QTELIV * CASE WHEN F80_TOTHT >= 0 THEN 1 ELSE -1 END AS quantite_livraison_approvisionnement,
F81_QTELIV * CASE WHEN F80_TOTHT >= 0 THEN 1 ELSE -1 END AS quantite_livraison_stockage,
round(F81_PRICOM * (1 - F81_TXTVAI/100),5) * F81_QTELIV * CASE WHEN F80_TOTHT >= 0 THEN 1 ELSE -1 END AS montant_livraison_ht,
round(F81_PRICOM * (1 - F81_TXTVAI/100),5) * F81_QTELIV + round(F81_PRICOM * (1 - F81_TXTVAI/100),5) * F81_QTELIV * COALESCE(w_TVA.taux,0) * CASE WHEN F80_TOTHT >= 0 THEN 1 ELSE -1 END AS montant_livraison_ttc,
CASE WHEN F81_QTELIV = F81_QTECOM THEN 'T' WHEN F81_QTELIV > F81_QTECOM THEN 'S' WHEN F81_QTELIV = 0 THEN 'N' ELSE 'P' END AS etat_livraison,
(F81_PRIFAC * F81_QTEFAC) * CASE WHEN F80_TOTHT >= 0 THEN 1 ELSE -1 END AS montant_liquidation_ht,
round(F81_PRIFAC * (F81_TXTVAI/100),5) * F81_QTEFAC AS montant_liquidation_remise,
round(F81_PRIFAC * (1- F81_TXTVAI/100),5) * F81_QTEFAC * COALESCE(w_TVA.taux,0) * CASE WHEN F80_TOTHT >= 0 THEN 1 ELSE -1 END AS montant_liquidation_tva,
0::numeric AS montant_liquidation_port,
round(F81_PRIFAC * (1- F81_TXTVAI/100),5) * F81_QTEFAC + round(F81_PRIFAC * (1- F81_TXTVAI/100),5) * F81_QTEFAC * COALESCE(w_TVA.taux,0) * CASE WHEN F80_TOTHT >= 0 THEN 1 ELSE -1 END AS montant_liquidation_ttc,
CASE WHEN F81_FACSOL = 'O' THEN '1' ELSE '0' END AS etat_liquidation
FROM w_F810 F_810
JOIN prod_cliwin.F_800 ON F80_NOCOM = F81_NOCOM AND F80_DACOM = F81_DACOM
JOIN eco.p_commandes ON C1CLEUNIK::text = p_commandes.code_original
JOIN w_f200 AS F_200 ON F_200.ARCLEUNIK = F_810.ARCLEUNIK
LEFT JOIN w_TVA ON F20_CODTVA = w_TVA.codtva AND date(F80_DACOM) BETWEEN w_TVA.date_debut AND w_TVA.date_fin
-- LEFT JOIN w_210 as F_210 ON F_210.LICLEUNIK = F_810.LICLEUNIK
LEFT JOIN eco.t_articles ON F_810.ARCLEUNIK::text = t_articles.code_original AND t_articles.oid <> 0
LEFT JOIN eco.t_compte ON F_810.compte_code_original = t_compte.code_original AND t_compte.oid <> 0
LEFT JOIN base.t_ucd ON ucd_code = t_ucd.code AND t_ucd.oid <> 0
LEFT JOIN base.t_lpp ON F20_CODTIPS = t_lpp.code
WHERE F81_DACOM >= '[ENV_ECO_ANNEEDEBUT]0101';
SELECT base.cti_enable_index('eco', 'i_ligne_commandes_1');
SELECT base.cti_enable_index('eco', 'i_ligne_commandes_2');
SELECT base.cti_enable_index('eco', 'i_ligne_commandes_3');
]]>
= '[ENV_ECO_ANNEEDEBUT]0101'
AND FR5_NUMDEM IS NOT NULL
GROUP BY 1,2;
INSERT INTO eco.p_lignes_commandes(
code_original,
commande_id,
ligne_commande,
texte,
article_id,
unite_approvisionnement_id,
compte_id,
ucd_id,
lpp_id,
quantite_approvisionnement,
prix_unitaire_approvisionnement,
multiplicateur_stockage,
quantite_stockage,
prix_unitaire_stockage,
montant_commande_ht,
montant_commande_remise,
montant_commande_tva,
montant_commande_port,
montant_commande_ttc,
quantite_livraison_approvisionnement,
quantite_livraison_stockage,
montant_livraison_ht,
montant_livraison_ttc,
etat_livraison,
montant_liquidation_ht,
montant_liquidation_remise,
montant_liquidation_tva,
montant_liquidation_port,
montant_liquidation_ttc,
etat_liquidation)
SELECT
FR5_NUMDEM || R5CLEUNIK::text AS code_original,
p_commandes.oid AS commande_id,
0::numeric AS ligne_commande,
'' AS texte,
COALESCE(t_articles.oid, 0) AS article_id,
0::bigint AS unite_approvisionnement_id,
COALESCE(t_compte.oid, t_articles.compte_id, 0) AS compte_id,
COALESCE(t_ucd.oid, 0) AS ucd_id,
COALESCE(t_lpp.oid, 0) AS lpp_id,
FR5_QTE * CASE WHEN FR5_PRIXHT >= 0 THEN 1 ELSE -1 END AS quantite_approvisionnement,
FR5_PRIXHT AS prix_unitaire_approvisionnement,
0::numeric AS multiplicateur_stockage,
0::numeric AS quantite_stockage,
0::numeric AS prix_unitaire_stockage,
(FR5_PRIXHT * FR5_QTE) * CASE WHEN FR5_PRIXHT >= 0 THEN 1 ELSE -1 END AS montant_commande_ht,
0::numeric AS montant_commande_remise,
(FR5_PRIXTC - FR5_PRIXHT) * FR5_QTE AS montant_commande_tva,
0::numeric AS montant_commande_port,
(FR5_PRIXTC - FR5_PRIXHT) * FR5_QTE AS montant_commande_ttc,
FR5_QTE * CASE WHEN FR5_PRIXHT >= 0 THEN 1 ELSE -1 END AS quantite_livraison_approvisionnement,
FR5_QTE * CASE WHEN FR5_PRIXHT >= 0 THEN 1 ELSE -1 END AS quantite_livraison_stockage,
(FR5_PRIXHT * FR5_QTE) * CASE WHEN FR5_PRIXHT >= 0 THEN 1 ELSE -1 END AS montant_livraison_ht,
(FR5_PRIXTC - FR5_PRIXHT) * FR5_QTE AS montant_livraison_ttc,
CASE WHEN FR5_QTE = FR5_QTE THEN 'T' WHEN FR5_QTE > FR5_QTE THEN 'S' WHEN FR5_QTE = 0 THEN 'N' ELSE 'P' END AS etat_livraison,
(CASE WHEN FR5_DAFAC IS NOT NULL THEN FR5_PRIXHT * FR5_QTE ELSE 0 END) AS montant_liquidation_ht,
0::numeric AS montant_liquidation_remise,
CASE WHEN FR5_DAFAC IS NOT NULL THEN (FR5_PRIXTC - FR5_PRIXHT) * FR5_QTE ELSE 0 END AS montant_liquidation_tva,
0::numeric AS montant_liquidation_port,
CASE WHEN FR5_DAFAC IS NOT NULL THEN (FR5_PRIXTC * FR5_QTE) ELSE 0 END AS montant_liquidation_ttc,
CASE WHEN FR5_DAFAC IS NOT NULL THEN '1' ELSE '0' END AS etat_liquidation
FROM w_r500 as F_R500
JOIN eco.p_commandes ON FR5_NUMDEM = p_commandes.code_original
JOIN w_f200 AS F_200 ON F_200.ARCLEUNIK = F_R500.ARCLEUNIK
LEFT JOIN eco.t_articles ON F_R500.ARCLEUNIK::text = t_articles.code_original AND t_articles.oid <> 0
LEFT JOIN eco.t_compte ON ''::text = t_compte.code_original AND t_compte.oid <> 0
LEFT JOIN base.t_ucd ON '' = t_ucd.code
LEFT JOIN base.t_lpp ON F20_CODTIPS = t_lpp.code
WHERE FR5_DDEMAN >= '[ENV_ECO_ANNEEDEBUT]0101';
]]>
0
;
DROP TABLE IF EXISTS w_stocks;
CREATE TEMP TABLE w_stocks AS
SELECT
t_articles.oid AS article_id,
F_500.ARCLEUNIK,
F_200.F20_DEPRIX AS F20_PRIX,
F_200.F20_PUMP,
date(date_trunc('month',F50_DATE) + interval '1 month' - interval '1 day') AS date_fin,
date(date_trunc('month',F50_DATE)) AS date_debut,
date_part('year',F50_DATE) * 12 + date_part('month',F50_DATE) AS mois_sequence,
COALESCE(t_ucd.oid,w_210_ucd.ucd_id,w_210_ucd_def.ucd_id,0) AS ucd_id,
COALESCE(t_lpp.oid,0) AS lpp_id,
COALESCE(t_compte.oid,t_articles.compte_id,0) AS compte_id,
0::bigint AS lieu_id,
coalesce(t_providers.oid, 0::bigint) AS provider_id,
MAX(t_fournisseurs.oid) AS fournisseur_id,
0.00 AS stock_quantite_debut,
0.00 AS stock_valeur_debut,
MAX(COALESCE(F_210.F21_PRIX,0)) AS F21_PRIX,
SUM(CASE WHEN F50_TYPE IN ('E', 'F', 'R') THEN F50_QTE ELSE 0 END) AS entree_quantite,
SUM(CASE WHEN F50_TYPE IN ('E', 'F', 'R') THEN
CASE
WHEN F50_PUTTC <> 0 THEN F50_QTE * F50_PUTTC
WHEN F50_PRIX <> 0 THEN F50_QTE * F50_PRIX * (1+COALESCE(w_TVA.taux,0))
ELSE F50_QTE * F50_PUMP * (1+COALESCE(w_TVA.taux,0))
END
ELSE 0 END) AS entree_montant,
SUM(CASE WHEN F50_TYPE IN ('E', 'F', 'R') AND F50_QTE > 0 THEN F50_QTE ELSE 0 END) AS entree_quantite_pump,
SUM(CASE WHEN F50_TYPE IN ('E', 'F', 'R') AND F50_QTE > 0 THEN
CASE
WHEN F50_PUTTC <> 0 THEN F50_QTE * F50_PUTTC
WHEN F50_PRIX <> 0 THEN F50_QTE * F50_PRIX * (1+COALESCE(w_TVA.taux,0))
ELSE F50_QTE * F50_PUMP * (1+COALESCE(w_TVA.taux,0))
END
ELSE 0 END) AS entree_montant_pump,
0.00 AS pump,
SUM(CASE WHEN F50_TYPE NOT IN ('E', 'F', 'R', 'I') THEN F50_QTE ELSE 0 END) AS sortie_quantite,
0.00 AS sortie_montant,
(MAX(Array[
F50_DATE::text || MOCLEUNIK::text,
(CASE WHEN F50_TYPE IN ('I') THEN F50_QTE ELSE F50_ASTK + CASE WHEN F50_TYPE IN ('E', 'F', 'R') THEN F50_QTE ELSE 0-F50_QTE END END)::text
]))[2]::numeric AS stock_quantite_fin,
0.00 AS stock_valeur_fin
FROM w_F500 F_500
JOIN w_f200 as F_200 ON F_200.ARCLEUNIK = F_500.ARCLEUNIK
LEFT JOIN w_TVA ON F20_CODTVA = w_TVA.codtva AND date(F_500.F50_DATE) BETWEEN w_TVA.date_debut AND w_TVA.date_fin
LEFT JOIN w_210 as F_210 ON
F_210.ARCLEUNIK = F_500.ARCLEUNIK AND
F_210.F21_IDDIST = F_500.FOCLEUNIK AND
date(F_500.F50_DATE) BETWEEN F21_DEBUT AND F21_FIN
LEFT JOIN eco.t_providers on t_providers.code = F_500.provider_code
LEFT JOIN eco.t_types_mouvements ON F50_TYPE = t_types_mouvements.code_original
LEFT JOIN eco.t_unites_fonctionnelles ON (t_unites_fonctionnelles.code_original = (F50_DEPT || '-' || F50_SERVI))
LEFT JOIN eco.t_articles ON F_500.ARCLEUNIK::text = t_articles.code_original AND t_articles.oid <> 0
LEFT JOIN eco.t_fournisseurs ON F_500.FOCLEUNIK::text = t_fournisseurs.code_original
LEFT JOIN eco.t_compte ON F_500.compte_code_original = t_compte.code_original AND t_compte.oid <> 0
LEFT JOIN base.t_ucd ON F21_UCD = t_ucd.code
LEFT JOIN base.t_lpp ON F20_CODTIPS = t_lpp.code
LEFT JOIN w_210_ucd ON F_500.ARCLEUNIK = w_210_ucd.ARCLEUNIK AND date(F_500.F50_DATE) BETWEEN w_210_ucd.date_debut AND w_210_ucd.date_fin
LEFT JOIN w_210_ucd w_210_ucd_def ON F_500.ARCLEUNIK = w_210_ucd_def.ARCLEUNIK AND w_210_ucd_def.date_fin = '20991231'
LEFT JOIN w_210_fournisseur ON F_500.ARCLEUNIK = w_210_fournisseur.ARCLEUNIK AND date(F_500.F50_DATE) BETWEEN w_210_fournisseur.date_debut AND w_210_fournisseur.date_fin
LEFT JOIN w_210_fournisseur w_210_fournisseur_2 ON F_500.ARCLEUNIK = w_210_fournisseur_2.ARCLEUNIK AND w_210_fournisseur_2.date_fin = '20991231'
WHERE date(F50_DATE) < date(date_trunc('month',now()) + interval '1 month')
GROUP BY 1,2,3,4,5,6,7,8,9,10,11,12
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;
SELECT base.cti_execute(
'INSERT INTO w_stocks (
article_id,
ARCLEUNIK,
F20_PRIX,
F20_PUMP,
F21_PRIX,
date_fin,
date_debut,
mois_sequence,
ucd_id,
lpp_id,
compte_id,
lieu_id,
provider_id,
fournisseur_id,
stock_quantite_debut,
stock_valeur_debut,
entree_quantite,
entree_montant,
entree_quantite_pump,
entree_montant_pump,
pump,
sortie_quantite,
sortie_montant,
stock_quantite_fin,
stock_valeur_fin
)
SELECT
w_stocks.article_id,
w_stocks.ARCLEUNIK,
w_stocks.F20_PRIX,
w_stocks.F20_PUMP,
w_stocks.F21_PRIX,
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.ucd_id,
w_stocks.lpp_id,
w_stocks.compte_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 entree_quantite,
0.00 AS entree_montant,
0.00 AS entree_quantite_pump,
0.00 AS entree_montant_pump,
0.00 AS pump,
0.00 AS sortie_quantite,
0.00 AS sortie_montant,
w_stocks.stock_quantite_fin,
0.00 AS stock_valeur_fin
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);
UPDATE w_stocks
SET stock_quantite_fin = F20_QTESTO
FROM w_f200 AS F_200
WHERE w_stocks.ARCLEUNIK = F_200.ARCLEUNIK AND
w_stocks.date_fin >= date(date_trunc('month',now())) AND
F20_QTESTO <> stock_quantite_fin
;
DROP TABLE IF EXISTS w_pump;
CREATE TEMP TABLE w_pump AS
SELECT w_stocks.article_id,
w_stocks.ARCLEUNIK,
w_stocks.date_fin,
MAX(w_stocks.F20_PRIX) AS F20_PRIX,
MAX(w_stocks.F20_PUMP) AS F20_PUMP,
MAX(w_stocks.F21_PRIX) AS F21_PRIX,
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(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 < 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
FROM w_stocks
JOIN w_stocks w_stocks_before ON
w_stocks.article_id = w_stocks_before.article_id AND
w_stocks.date_fin >= w_stocks_before.date_fin
GROUP BY 1,2,3;
CREATE INDEX w_pump_i1 ON w_pump USING btree (article_id);
UPDATE w_stocks SET
pump = CASE WHEN pump6 <> 0 THEN pump6 WHEN pump12 <> 0 THEN pump12 WHEN w_pump.pump <> 0 THEN w_pump.pump WHEN w_pump.F21_PRIX <> 0 THEN w_pump.F21_PRIX ELSE w_pump.F20_PUMP END,
sortie_montant = sortie_quantite * CASE WHEN pump6 <> 0 THEN pump6 WHEN pump12 <> 0 THEN pump12 WHEN w_pump.pump <> 0 THEN w_pump.pump WHEN w_pump.F21_PRIX <> 0 THEN w_pump.F21_PRIX ELSE w_pump.F20_PUMP END,
stock_valeur_fin = w_stocks.stock_quantite_fin * CASE WHEN pump6 <> 0 THEN pump6 WHEN pump12 <> 0 THEN pump12 WHEN w_pump.pump <> 0 THEN w_pump.pump WHEN w_pump.F21_PRIX <> 0 THEN w_pump.F21_PRIX ELSE w_pump.F20_PUMP END
FROM w_pump
WHERE w_pump.article_id = w_stocks.article_id AND
w_pump.date_fin = w_stocks.date_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) <= '20091231'
);
UPDATE w_stocks SET
stock_quantite_debut = w_stocks_before.stock_quantite_fin,
stock_valeur_debut = w_stocks_before.stock_valeur_fin
FROM w_stocks w_stocks_before
WHERE w_stocks_before.article_id = w_stocks.article_id 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,
provider_id,
fournisseur_id,
stock_quantite_debut,
stock_valeur_debut,
entree_quantite,
entree_montant,
pump,
sortie_quantite,
sortie_montant,
stock_quantite_fin,
stock_valeur_fin)
SELECT
article_id,
date_fin,
date_debut,
ucd_id,
lpp_id,
compte_id,
lieu_id,
provider_id,
fournisseur_id,
stock_quantite_debut,
stock_valeur_debut,
entree_quantite,
entree_montant,
pump,
sortie_quantite,
sortie_montant,
stock_quantite_fin,
stock_valeur_fin
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');
]]>
0 THEN F50_PUTTC / (1+COALESCE(w_TVA.taux,0))
WHEN F50_TYPE IN ('E', 'F', 'R') AND F50_PRIX <> 0 THEN F50_PRIX
WHEN F50_TYPE IN ('E', 'F', 'R') THEN F50_PUMP
WHEN F50_TYPE NOT IN ('E', 'F', 'R') AND F50_PUMP <> 0 THEN F50_PUMP
WHEN F50_TYPE NOT IN ('E', 'F', 'R') THEN F50_PRIX
ELSE 0
END AS prix_unitaire,
CASE WHEN F50_TYPE IN ('E', 'F', 'R') THEN F50_QTE ELSE 0 END AS entree_quantite,
CASE WHEN F50_TYPE NOT IN ('E', 'F', 'R') THEN F50_QTE ELSE 0 END AS sortie_quantite,
CASE WHEN F50_TYPE IN ('E', 'F', 'R') THEN
CASE
WHEN F50_PUTTC <> 0 THEN F50_QTE * F50_PUTTC
WHEN F50_PRIX <> 0 THEN F50_QTE * F50_PRIX * (1+COALESCE(w_TVA.taux,0))
ELSE F50_QTE * F50_PUMP * (1+COALESCE(w_TVA.taux,0))
END
ELSE 0 END AS entree_montant,
round(CASE WHEN F50_TYPE IN ('E', 'F', 'R') THEN
CASE
WHEN F50_PUTTC <> 0 THEN F50_QTE * F50_PUTTC / (1+COALESCE(w_TVA.taux,0))
WHEN F50_PRIX <> 0 THEN F50_QTE * F50_PRIX
ELSE F50_QTE * F50_PUMP
END
ELSE 0 END,2) AS entree_montant_ht,
CASE WHEN F50_TYPE NOT IN ('E', 'F', 'R') THEN
CASE
WHEN F50_PUTTC <> 0 THEN F50_QTE * F50_PUTTC
WHEN F50_PRIX <> 0 THEN F50_QTE * F50_PRIX * (1+COALESCE(w_TVA.taux,0))
WHEN F50_PUMP <> 0 THEN F50_QTE * F50_PUMP * (1+COALESCE(w_TVA.taux,0))
ELSE F50_QTE * p_stock.pump * (1+COALESCE(w_TVA.taux,0))
END
ELSE 0 END AS sortie_montant,
CASE WHEN F50_TYPE NOT IN ('E', 'F', 'R') THEN
CASE
WHEN F50_PUTTC <> 0 THEN F50_QTE * F50_PUTTC / (1+COALESCE(w_TVA.taux,0))
WHEN F50_PRIX <> 0 THEN F50_QTE * F50_PRIX
WHEN F50_PUMP <> 0 THEN F50_QTE * F50_PUMP
ELSE F50_QTE * p_stock.pump
END
ELSE 0 END AS sortie_montant_ht,
CASE WHEN F50_TYPE NOT IN ('E', 'F', 'R') THEN
CASE
WHEN F50_PUMP <> 0 THEN F50_QTE * F50_PUMP * (1+COALESCE(w_TVA.taux,0))
ELSE F50_QTE * F50_PRIX * (1+COALESCE(w_TVA.taux,0))
END
ELSE 0 END AS sortie_montant_original_ttc,
CASE WHEN F50_TYPE NOT IN ('E', 'F', 'R') THEN
CASE
WHEN F50_PUMP <> 0 THEN F50_QTE * F50_PUMP
ELSE F50_QTE * F50_PRIX
END
ELSE 0 END AS sortie_montant_original_ht
FROM w_F500 F_500
JOIN w_f200 AS F_200 ON F_200.ARCLEUNIK = F_500.ARCLEUNIK
LEFT JOIN eco.t_providers on t_providers.code = F_500.provider_code
LEFT JOIN w_TVA ON F20_CODTVA = w_TVA.codtva AND date(F_500.F50_DATE) BETWEEN w_TVA.date_debut AND w_TVA.date_fin
LEFT JOIN w_210 as F_210 ON
F_210.ARCLEUNIK = F_500.ARCLEUNIK AND
F_210.F21_IDDIST = F_500.FOCLEUNIK AND
date(F_500.F50_DATE) BETWEEN F21_DEBUT AND F21_FIN
LEFT JOIN eco.t_types_mouvements ON F50_TYPE = t_types_mouvements.code_original
LEFT JOIN eco.t_unites_fonctionnelles ON (t_unites_fonctionnelles.code_original = (F50_DEPT || '-' || F50_SERVI))
LEFT JOIN eco.t_articles ON F_500.ARCLEUNIK::text = t_articles.code_original AND t_articles.oid <> 0
LEFT JOIN eco.t_fournisseurs ON F_500.FOCLEUNIK::text = t_fournisseurs.code_original
LEFT JOIN eco.t_compte ON F_500.compte_code_original = t_compte.code_original AND t_compte.oid <> 0
LEFT JOIN eco.t_lieux ON F_500.F50_STOCK = t_lieux.code_original AND t_lieux.oid <> 0
LEFT JOIN base.t_ucd ON F21_UCD = t_ucd.code
LEFT JOIN base.t_lpp ON F20_CODTIPS = t_lpp.code
LEFT JOIN w_210_ucd ON F_500.ARCLEUNIK = w_210_ucd.ARCLEUNIK AND date(F_500.F50_DATE) BETWEEN w_210_ucd.date_debut AND w_210_ucd.date_fin
LEFT JOIN w_210_ucd w_210_ucd_def ON F_500.ARCLEUNIK = w_210_ucd_def.ARCLEUNIK AND w_210_ucd_def.date_fin = '20991231'
LEFT JOIN w_210_fournisseur ON F_500.ARCLEUNIK = w_210_fournisseur.ARCLEUNIK AND date(F_500.F50_DATE) BETWEEN w_210_fournisseur.date_debut AND w_210_fournisseur.date_fin
LEFT JOIN w_210_fournisseur w_210_fournisseur_2 ON F_500.ARCLEUNIK = w_210_fournisseur_2.ARCLEUNIK AND w_210_fournisseur_2.date_fin = '20991231'
LEFT JOIN eco.p_stock ON p_stock.article_id =t_articles.oid AND
date(F50_DATE) BETWEEN p_stock.date_debut AND p_stock.date_fin
WHERE F50_DATE >= '[ENV_ECO_ANNEEDEBUT]0101' AND F50_TYPE <> 'I';
INSERT INTO eco.p_mouvements_articles(
code_original,
provider_id,
date,
sens_mouvement,
type_mouvement_id,
texte,
gestionnaire_id,
lieu_id,
unite_fonctionnelle_id,
article_id,
compte_id,
fournisseur_id,
commande_id,
ligne_commande,
ucd_id,
lpp_id,
prix_unitaire,
entree_quantite,
sortie_quantite,
entree_montant,
entree_montant_ht,
sortie_montant,
sortie_montant_ht,
sortie_montant_original_ttc,
sortie_montant_original_ht)
SELECT
'R'::text || F_R500.R5CLEUNIK::text AS code_original,
coalesce(t_providers.oid, 0::bigint) AS provider_id,
FR5_DATE AS date,
'E' AS sens_mouvement,
COALESCE(t_types_mouvements.oid,0) AS type_mouvement_id,
''::text AS texte,
0::bigint AS gestionnaire_id,
0::bigint AS lieu_id,
COALESCE(t_unites_fonctionnelles.oid,0) AS unite_fonctionnelle_id,
COALESCE(t_articles.oid,0) AS article_id,
COALESCE(t_compte.oid,t_articles.compte_id,0) AS compte_id,
COALESCE(t_fournisseurs.oid,w_210_fournisseur.fournisseur_id, w_210_fournisseur_2.fournisseur_id,0) AS fournisseur_id,
0::bigint AS commande_id,
0::numeric AS ligne_commande,
COALESCE(t_ucd.oid,w_210_ucd.ucd_id,w_210_ucd_def.ucd_id,0) AS ucd_id,
COALESCE(t_lpp.oid,0) AS lpp_id,
CASE
WHEN FR5_PRIXTC <> 0 THEN FR5_PRIXTC / (1+COALESCE(w_TVA.taux,0))
WHEN FR5_PRIXHT <> 0 THEN FR5_PRIXHT
ELSE 0
END AS prix_unitaire,
FR5_QTE AS entree_quantite,
0 AS sortie_quantite,
CASE
WHEN FR5_PRIXTC <> 0 THEN FR5_QTE * FR5_PRIXTC
WHEN FR5_PRIXHT <> 0 THEN FR5_QTE * FR5_PRIXHT * (1+COALESCE(w_TVA.taux,0))
ELSE 0 END
AS entree_montant,
round(
CASE
WHEN FR5_PRIXTC <> 0 THEN FR5_QTE * FR5_PRIXTC / (1+COALESCE(w_TVA.taux,0))
WHEN FR5_PRIXHT <> 0 THEN FR5_QTE * FR5_PRIXHT
ELSE 0
END,2) AS entree_montant_ht,
0 AS sortie_montant,
0 AS sortie_montant_ht,
0 AS sortie_montant_original_ttc,
0 AS sortie_montant_original_ht
FROM w_r500 as F_R500
JOIN w_f200 AS F_200 ON F_200.ARCLEUNIK = F_R500.ARCLEUNIK
LEFT JOIN eco.t_providers on t_providers.code = F_R500.provider_code
LEFT JOIN w_TVA ON F20_CODTVA = w_TVA.codtva AND date(F_R500.FR5_DATE) BETWEEN w_TVA.date_debut AND w_TVA.date_fin
LEFT JOIN w_210 as F_210 ON
F_210.ARCLEUNIK = F_R500.ARCLEUNIK AND
F_210.F21_IDDIST = F_R500.FOCLEUNIK AND
date(F_R500.FR5_DATE) BETWEEN F21_DEBUT AND F21_FIN
LEFT JOIN eco.t_types_mouvements ON 'E' = t_types_mouvements.code_original
LEFT JOIN eco.t_unites_fonctionnelles ON (t_unites_fonctionnelles.code_original = (FR5_CDEPT || '-' || FR5_CSERVI))
LEFT JOIN eco.t_articles ON F_R500.ARCLEUNIK::text = t_articles.code_original AND t_articles.oid <> 0
LEFT JOIN eco.t_fournisseurs ON F_R500.FOCLEUNIK::text = t_fournisseurs.code_original
LEFT JOIN eco.t_compte ON ''::text = t_compte.code_original AND t_compte.oid <> 0
LEFT JOIN base.t_ucd ON F21_UCD = t_ucd.code
LEFT JOIN base.t_lpp ON F20_CODTIPS = t_lpp.code
LEFT JOIN w_210_ucd ON F_R500.ARCLEUNIK = w_210_ucd.ARCLEUNIK AND date(F_R500.FR5_DATE) BETWEEN w_210_ucd.date_debut AND w_210_ucd.date_fin
LEFT JOIN w_210_ucd w_210_ucd_def ON F_R500.ARCLEUNIK = w_210_ucd_def.ARCLEUNIK AND w_210_ucd_def.date_fin = '20991231'
LEFT JOIN w_210_fournisseur ON F_R500.ARCLEUNIK = w_210_fournisseur.ARCLEUNIK AND date(F_R500.FR5_DATE) BETWEEN w_210_fournisseur.date_debut AND w_210_fournisseur.date_fin
LEFT JOIN w_210_fournisseur w_210_fournisseur_2 ON F_R500.ARCLEUNIK = w_210_fournisseur_2.ARCLEUNIK AND w_210_fournisseur_2.date_fin = '20991231'
LEFT JOIN eco.p_stock ON p_stock.article_id =t_articles.oid AND
date(FR5_DATE) BETWEEN p_stock.date_debut AND p_stock.date_fin
WHERE FR5_DATE >= '[ENV_ECO_ANNEEDEBUT]0101' AND
date(FR5_DATE) <= now();
--INSERT INTO eco.p_mouvements_articles(
-- code_original,
-- provider_id,
-- date,
-- sens_mouvement,
-- type_mouvement_id,
-- texte,
-- gestionnaire_id,
-- lieu_id,
-- unite_fonctionnelle_id,
-- article_id,
-- compte_id,
-- fournisseur_id,
-- commande_id,
-- ligne_commande,
-- ucd_id,
-- lpp_id,
-- prix_unitaire,
-- entree_quantite,
-- sortie_quantite,
-- entree_montant,
-- entree_montant_ht,
-- sortie_montant,
-- sortie_montant_ht,
-- sortie_montant_original_ttc,
-- sortie_montant_original_ht)
--SELECT
-- 'R2'::text || F_R500.R5CLEUNIK::text AS code_original,
-- coalesce(t_providers.oid, 0::bigint) AS provider_id,
-- FR5_DATE AS date,
-- 'E' AS sens_mouvement,
-- COALESCE(t_types_mouvements.oid,0) AS type_mouvement_id,
-- ''::text AS texte,
-- 0::bigint AS gestionnaire_id,
-- 0::bigint AS lieu_id,
-- COALESCE(t_unites_fonctionnelles.oid,0) AS unite_fonctionnelle_id,
-- COALESCE(t_articles.oid,0) AS article_id,
-- COALESCE(t_compte.oid,t_articles.compte_id,0) AS compte_id,
-- COALESCE(t_fournisseurs.oid,w_210_fournisseur.fournisseur_id, w_210_fournisseur_2.fournisseur_id,0) AS fournisseur_id,
-- 0::bigint AS commande_id,
-- 0::numeric AS ligne_commande,
-- COALESCE(t_ucd.oid,w_210_ucd.ucd_id,w_210_ucd_def.ucd_id,0) AS ucd_id,
-- COALESCE(t_lpp.oid,0) AS lpp_id,
-- CASE
-- WHEN FR5_PRIXTC <> 0 THEN FR5_PRIXTC / (1+COALESCE(w_TVA.taux,0))
-- WHEN FR5_PRIXHT <> 0 THEN FR5_PRIXHT
-- ELSE 0
-- END AS prix_unitaire,
-- FR5_QTE AS entree_quantite,
-- 0 AS sortie_quantite,
-- CASE
-- WHEN FR5_PRIXTC <> 0 THEN FR5_QTE * FR5_PRIXTC
-- WHEN FR5_PRIXHT <> 0 THEN FR5_QTE * FR5_PRIXHT * (1+COALESCE(w_TVA.taux,0))
-- ELSE 0 END
-- AS entree_montant,
-- round(
-- CASE
-- WHEN FR5_PRIXTC <> 0 THEN FR5_QTE * FR5_PRIXTC / (1+COALESCE(w_TVA.taux,0))
-- WHEN FR5_PRIXHT <> 0 THEN FR5_QTE * FR5_PRIXHT
-- ELSE 0
-- END,2) AS entree_montant_ht,
-- 0 AS sortie_montant,
-- 0 AS sortie_montant_ht,
-- 0 AS sortie_montant_original_ttc,
-- 0 AS sortie_montant_original_ht
--FROM w_r500 as F_R500
-- JOIN w_f200 AS F_200 ON F_200.ARCLEUNIK = F_R500.ARCLEUNIK
-- LEFT JOIN eco.t_providers on t_providers.code = F_R500.provider_code
-- LEFT JOIN w_TVA ON F20_CODTVA = w_TVA.codtva AND date(F_R500.FR5_DATE) BETWEEN w_TVA.date_debut AND w_TVA.date_fin
-- LEFT JOIN w_210 as F_210 ON
-- F_210.ARCLEUNIK = F_R500.ARCLEUNIK AND
-- F_210.F21_IDDIST = F_R500.FOCLEUNIK AND
-- date(F_R500.FR5_DATE) BETWEEN F21_DEBUT AND F21_FIN
-- LEFT JOIN eco.t_types_mouvements ON '' = t_types_mouvements.code_original
-- LEFT JOIN eco.t_unites_fonctionnelles ON (t_unites_fonctionnelles.code_original = (FR5_CDEPT || '-' || FR5_CSERVI))
-- LEFT JOIN eco.t_articles ON F_R500.ARCLEUNIK::text = t_articles.code_original AND t_articles.oid <> 0
-- LEFT JOIN eco.t_fournisseurs ON F_R500.FOCLEUNIK::text = t_fournisseurs.code_original
-- LEFT JOIN eco.t_compte ON ''::text = t_compte.code_original AND t_compte.oid <> 0
-- LEFT JOIN base.t_ucd ON F21_UCD = t_ucd.code
-- LEFT JOIN base.t_lpp ON F20_CODTIPS = t_lpp.code
-- LEFT JOIN w_210_ucd ON F_R500.ARCLEUNIK = w_210_ucd.ARCLEUNIK AND date(F_R500.FR5_DATE) BETWEEN w_210_ucd.date_debut AND w_210_ucd.date_fin
-- LEFT JOIN w_210_ucd w_210_ucd_def ON F_R500.ARCLEUNIK = w_210_ucd_def.ARCLEUNIK AND w_210_ucd_def.date_fin = '20991231'
-- LEFT JOIN w_210_fournisseur ON F_R500.ARCLEUNIK = w_210_fournisseur.ARCLEUNIK AND date(F_R500.FR5_DATE) BETWEEN w_210_fournisseur.date_debut AND w_210_fournisseur.date_fin
-- LEFT JOIN w_210_fournisseur w_210_fournisseur_2 ON F_R500.ARCLEUNIK = w_210_fournisseur_2.ARCLEUNIK AND w_210_fournisseur_2.date_fin = '20991231'
-- LEFT JOIN eco.p_stock ON p_stock.article_id =t_articles.oid AND
-- date(FR5_DATE) BETWEEN p_stock.date_debut AND p_stock.date_fin
--WHERE FR5_DATE >= '[ENV_ECO_ANNEEDEBUT]0101' AND
-- date(FR5_DATE) <= now();
SELECT base.cti_enable_index('eco', 'i_mouvements_articles_1');
SELECT base.cti_enable_index('eco', 'i_mouvements_articles_2');
SELECT base.cti_enable_index('eco', 'i_mouvements_articles_3');
SELECT base.cti_enable_index('eco', 'i_mouvements_articles_4');
SELECT base.cti_enable_index('eco', 'i_mouvements_articles_5');
SELECT base.cti_enable_index('eco', 'i_mouvements_articles_6');
SELECT base.cti_enable_index('eco', 'i_mouvements_articles_7');
SELECT base.cti_enable_index('eco', 'i_mouvements_articles_8');
SELECT base.cti_enable_index('eco', 'i_mouvements_articles_9');
SELECT base.cti_enable_index('eco', 'i_mouvements_articles_10');
]]>