You can not select more than 25 topics Topics must start with a letter or number, can include dashes ('-') and can be up to 35 characters long.
 
 
 

1196 lines
50 KiB

<?xml version="1.0" encoding="ISO-8859-1"?>
<ROOT>
<NODE name="INIT" label="INITIALISATIONS SAGE 100">
<NODE label="Tables Articles">
<sqlcmd><![CDATA[
-- Préparation
DROP TABLE IF EXISTS w_TPRODUIT;
CREATE TEMP TABLE w_TPRODUIT AS
SELECT *,
'E'::text AS NOMENCLATURE,
''::text AS OIDCATEGORIECOMMERCIAL,
''::text AS OIDCATEGORIECOMPTAPRODUIT,
''::text AS OIDCATEGORIECOMPTAPRODUIT_2,
''::text AS OIDCOMPTEGENERAL,
''::text AS compte_numero,
''::text AS OIDTIERS,
''::text AS TYPE_TVA,
1::numeric AS taux_tva_1,
1::numeric AS taux_tva_2
FROM prod_sage100compta.TPRODUIT
;
SELECT base.cti_execute('
UPDATE w_TPRODUIT
SET OIDCATEGORIECOMMERCIAL = subview.OIDCATEGORIECOMMERCIAL,
OIDCATEGORIECOMPTAPRODUIT = subview.OIDCATEGORIECOMPTAPRODUIT,
OIDCATEGORIECOMPTAPRODUIT_2 = subview.OIDCATEGORIECOMPTAPRODUIT_2,
OIDTIERS = subview.OIDTIERS,
TYPE_TVA = subview.TYPE_TVA
FROM
(
SELECT OIDPRODUIT,
max(OIDCATEGORIECOMMERCIAL) AS OIDCATEGORIECOMMERCIAL,
max(OIDCATEGORIECOMPTAPRODUIT) AS OIDCATEGORIECOMPTAPRODUIT,
min(OIDCATEGORIECOMPTAPRODUIT) AS OIDCATEGORIECOMPTAPRODUIT_2,
MAX(COALESCE(TROLETIERS.OIDTIERS,'''')) AS OIDTIERS,
MAX(COALESCE(TCATEGORIEFACTURATION.CODE,'''')) AS TYPE_TVA
FROM prod_sage100compta.TPRODUITCOMMERCIAL
LEFT JOIN prod_sage100compta.TROLETIERS ON OIDFOURNISSEUR = TROLETIERS.OID
LEFT JOIN prod_sage100compta.TREPARTITIONFACTURATION ON TREPARTITIONFACTURATION.OIDPRODUITCOMMERCIAL = TPRODUITCOMMERCIAL.OID
LEFT JOIN prod_sage100compta.TCATEGORIEFACTURATION ON TREPARTITIONFACTURATION.OIDCATEGORIEFACTURATION = TCATEGORIEFACTURATION.OID
GROUP BY 1
) subview
WHERE w_TPRODUIT.OID = OIDPRODUIT
',1)
WHERE 'oidfournisseur' IN (SELECT column_name FROM information_schema.columns WHERE table_name ILIKE 'TPRODUITCOMMERCIAL')
;
SELECT base.cti_execute('
UPDATE w_TPRODUIT SET
OIDCOMPTEGENERAL = OIDCOMPTEGENERALDEBIT
FROM prod_sage100compta.TSCHEMACOMPTAPRODUIT
WHERE w_TPRODUIT.OIDCATEGORIECOMPTAPRODUIT = TSCHEMACOMPTAPRODUIT.OIDCATEGORIECOMPTAPRODUIT',1)
WHERE 'oidcomptegeneraldebit' IN (SELECT column_name FROM information_schema.columns WHERE table_name ILIKE 'TPRODUITCOMMERCIAL')
;
SELECT base.cti_execute('
UPDATE w_TPRODUIT SET
OIDCOMPTEGENERAL = OIDCOMPTEGENERALDEBIT,
OIDCATEGORIECOMPTAPRODUIT = OIDCATEGORIECOMPTAPRODUIT_2
FROM prod_sage100compta.TSCHEMACOMPTAPRODUIT
WHERE w_TPRODUIT.OIDCATEGORIECOMPTAPRODUIT_2 = TSCHEMACOMPTAPRODUIT.OIDCATEGORIECOMPTAPRODUIT
',1)
WHERE 'oidcomptegeneraldebit' IN (SELECT column_name FROM information_schema.columns WHERE table_name ILIKE 'TSCHEMACOMPTAPRODUIT')
;
UPDATE w_TPRODUIT
SET compte_numero = CODECOMPTE
FROM prod_sage100compta.TCOMPTEGENERAL
WHERE TCOMPTEGENERAL.OID = OIDCOMPTEGENERAL
;
UPDATE w_TPRODUIT SET
taux_tva_1 = CASE TYPE_TVA
WHEN 'NORMAL' THEN 1.20
WHEN 'REDUIT' THEN 1.055
WHEN 'REDUIT 2.1' THEN 1.021
ELSE 1 END,
taux_tva_2 = CASE TYPE_TVA
WHEN 'NORMAL' THEN 1.196
WHEN 'REDUIT' THEN 1.055
WHEN 'REDUIT 2.1' THEN 1.021
ELSE 1 END
;
-- Unites de stockage
-- LPP
-- UCD
-- ATC
-- Standard ATC
SELECT eco.cti_reorganize_classification_atc();
-- Comptes
INSERT INTO eco.t_compte(code_original, code, texte, texte_court)
SELECT
CODECOMPTE code_original,
CODECOMPTE AS code,
MAX(CAPTION) AS texte,
MAX(CAPTION) AS texte_court
FROM prod_sage100compta.TCOMPTEGENERAL
WHERE OID IN (SELECT OIDCOMPTEGENERAL FROM w_TPRODUIT) AND
CODECOMPTE NOT IN (SELECT code_original FROM eco.t_compte WHERE code_original IS NOT NULL)
GROUP BY 1
ORDER BY 1;
-- Types d'articles
INSERT INTO eco.t_types_articles(code_original, code, texte, texte_court)
SELECT NOMENCLATURE,NOMENCLATURE,NOMENCLATURE,NOMENCLATURE
FROM w_TPRODUIT
WHERE NOMENCLATURE NOT IN (SELECT code_original FROM eco.t_types_articles WHERE code_original IS NOT NULL)
GROUP BY 1,2,3,4
ORDER BY 1;
-- Familles d'articles
INSERT INTO eco.t_familles_articles(code_original, code, texte, texte_court)
SELECT TCATEGORIECOMMERCIALPRODUIT.OID,
substr(TCATEGORIECOMMERCIALPRODUIT.CODE,1,30),
MAX(TCATEGORIECOMMERCIALPRODUIT.CAPTION),
SUBSTR(MAX(TCATEGORIECOMMERCIALPRODUIT.CAPTION),50)
FROM prod_sage100compta.TCATEGORIECOMMERCIALPRODUIT
WHERE TCATEGORIECOMMERCIALPRODUIT.OID <> '' AND
TCATEGORIECOMMERCIALPRODUIT.OID IN (SELECT OIDCATEGORIECOMMERCIAL FROM w_TPRODUIT) AND
TCATEGORIECOMMERCIALPRODUIT.OID NOT IN (SELECT code_original FROM eco.t_familles_articles WHERE code_original IS NOT NULL)
GROUP BY 1,2
ORDER BY 2;
UPDATE eco.t_familles_articles
SET texte = CAPTION,
texte_court = CAPTION
FROM prod_sage100compta.TCATEGORIECOMMERCIALPRODUIT
WHERE TCATEGORIECOMMERCIALPRODUIT.OID = code_original AND
(texte IS DISTINCT FROM CAPTION OR
texte_court IS DISTINCT FROM SUBSTR(TCATEGORIECOMMERCIALPRODUIT.CAPTION,50))
;
-- Sous familles
-- Catégories
INSERT INTO eco.t_categories_articles(code_original, code, texte, texte_court)
SELECT TCATEGORIECOMPTAPRODUIT.OID,
TCATEGORIECOMPTAPRODUIT.CODE,
MAX(TCATEGORIECOMPTAPRODUIT.CAPTION),
MAX(TCATEGORIECOMPTAPRODUIT.CAPTION)
FROM prod_sage100compta.TCATEGORIECOMPTAPRODUIT
WHERE TCATEGORIECOMPTAPRODUIT.OID <> '' AND
TCATEGORIECOMPTAPRODUIT.OID IN (SELECT OIDCATEGORIECOMPTAPRODUIT FROM w_TPRODUIT) AND
TCATEGORIECOMPTAPRODUIT.OID NOT IN (SELECT code_original FROM eco.t_categories_articles WHERE code_original IS NOT NULL)
GROUP BY 1,2
ORDER BY 2;
UPDATE eco.t_categories_articles
SET texte = CAPTION,
texte_court = CAPTION
FROM prod_sage100compta.TCATEGORIECOMPTAPRODUIT
WHERE TCATEGORIECOMPTAPRODUIT.OID = code_original AND
(texte IS DISTINCT FROM CAPTION OR
texte_court IS DISTINCT FROM CAPTION);
-- Sous catégories
-- Articles
INSERT INTO eco.t_articles(code_original, code, texte, texte_court)
SELECT TPRODUIT.OID,
substr(TPRODUIT.CODE,1,30),
TPRODUIT.CAPTION,
substr(TPRODUIT.CAPTION,1,50)
FROM w_TPRODUIT TPRODUIT
LEFT JOIN eco.t_articles ON TPRODUIT.OID = code_original
WHERE TPRODUIT.OID IN
(SELECT DISTINCT TPRODUITCOMMERCIAL.OIDPRODUIT
FROM prod_sage100compta.TDETAILLIVRAISON
JOIN prod_sage100compta.TPRODUITCOMMERCIAL ON OIDPRODUITCOMMERCIAL = TPRODUITCOMMERCIAL.OID
) AND
code_original IS NULL;
UPDATE eco.t_articles
SET
texte = CAPTION,
texte_court = substr(CAPTION,1,50)
FROM prod_sage100compta.TPRODUIT
WHERE code_original = TPRODUIT.OID
AND (
texte IS DISTINCT FROM CAPTION OR
texte_court IS DISTINCT FROM substr(CAPTION,1,50))
;
UPDATE eco.t_articles SET
type_id = COALESCE(t_types_articles.oid,0),
famille_id = COALESCE(t_familles_articles.oid,0),
sous_famille_id = COALESCE(t_sous_familles_articles.oid,0),
categorie_id = COALESCE(t_categories_articles.oid,0),
sous_categorie_id = COALESCE(t_sous_categories_articles.oid,0),
classification_atc_id = COALESCE(t_classification_atc.oid,0),
unite_stockage_id = COALESCE(t_unites_stockage.oid,0),
unite_distribution_id = COALESCE(t_unites_distribution.oid,0),
lpp_id = COALESCE(t_lpp.oid,0),
ucd_id = COALESCE(t_ucd.oid,0)
FROM w_TPRODUIT TPRODUIT
LEFT JOIN eco.t_familles_articles ON OIDCATEGORIECOMMERCIAL = t_familles_articles.code_original
LEFT JOIN eco.t_sous_familles_articles ON t_sous_familles_articles.oid = 0
LEFT JOIN eco.t_types_articles ON NOMENCLATURE = upper(t_types_articles.code_original)
LEFT JOIN eco.t_classification_atc ON t_classification_atc.oid = 0
LEFT JOIN eco.t_categories_articles ON OIDCATEGORIECOMPTAPRODUIT = t_categories_articles.code_original
LEFT JOIN eco.t_sous_categories_articles ON t_sous_categories_articles.oid = 0
LEFT JOIN eco.t_unites t_unites_stockage ON t_unites_stockage.oid = 0
LEFT JOIN eco.t_unites t_unites_distribution ON t_unites_distribution.oid = 0
LEFT JOIN base.t_lpp ON t_lpp.oid = 0
LEFT JOIN base.t_ucd ON t_ucd.oid = 0
WHERE
t_articles.code_original = TPRODUIT.OID AND
(t_articles.type_id IS DISTINCT FROM COALESCE(t_types_articles.oid,0) OR
t_articles.famille_id IS DISTINCT FROM COALESCE(t_familles_articles.oid,0) OR
t_articles.sous_famille_id IS DISTINCT FROM COALESCE(t_sous_familles_articles.oid,0) OR
t_articles.categorie_id IS DISTINCT FROM COALESCE(t_categories_articles.oid,0) OR
t_articles.sous_categorie_id IS DISTINCT FROM COALESCE(t_sous_categories_articles.oid,0) OR
t_articles.classification_atc_id IS DISTINCT FROM COALESCE(t_classification_atc.oid,0) OR
t_articles.unite_stockage_id IS DISTINCT FROM COALESCE(t_unites_stockage.oid,0) OR
t_articles.unite_distribution_id IS DISTINCT FROM COALESCE(t_unites_distribution.oid,0) OR
lpp_id IS DISTINCT FROM COALESCE(t_lpp.oid,0) OR
ucd_id IS DISTINCT FROM COALESCE(t_ucd.oid,0)
);
UPDATE eco.t_articles SET
compte_id = COALESCE(t_compte.oid,0)
FROM w_TPRODUIT TPRODUIT
LEFT JOIN eco.t_compte ON compte_numero = t_compte.code_original
WHERE
t_articles.code_original = TPRODUIT.OID AND
(
t_articles.compte_id IS DISTINCT FROM COALESCE(t_compte.oid,0)
);
UPDATE eco.t_articles SET compte_id = 0 WHERE compte_id IS NULL
;
UPDATE eco.t_articles
SET gere_en_stock = '1'
FROM w_TPRODUIT TPRODUIT
WHERE TPRODUIT.OID = code_original AND
gere_en_stock != '1'
;
UPDATE eco.t_articles SET
type_code = t_types_articles.code,
type_texte = t_types_articles.texte_court,
type_section_id = t_types_articles.section_id,
type_section_code = t_types_articles.section_code,
type_section_texte = t_types_articles.section_texte,
famille_code = t_familles_articles.code,
famille_texte = t_familles_articles.texte_court,
famille_section_id = t_familles_articles.section_id,
famille_section_code = t_familles_articles.section_code,
famille_section_texte = t_familles_articles.section_texte,
sous_famille_code = t_sous_familles_articles.code,
sous_famille_texte = t_sous_familles_articles.texte_court,
sous_famille_section_id = t_sous_familles_articles.section_id,
sous_famille_section_code = t_sous_familles_articles.section_code,
sous_famille_section_texte = t_sous_familles_articles.section_texte,
categorie_code = t_categories_articles.code,
categorie_texte = t_categories_articles.texte_court,
categorie_section_id = t_categories_articles.section_id,
categorie_section_code = t_categories_articles.section_code,
categorie_section_texte = t_categories_articles.section_texte,
sous_categorie_code = t_sous_categories_articles.code,
sous_categorie_texte = t_sous_categories_articles.texte_court,
sous_categorie_section_id = t_sous_categories_articles.section_id,
sous_categorie_section_code = t_sous_categories_articles.section_code,
sous_categorie_section_texte = t_sous_categories_articles.section_texte,
classification_atc_code = t_classification_atc.code,
classification_atc_texte = t_classification_atc.texte_court,
classification_atc_section_id = t_classification_atc.section_id,
classification_atc_section_code = t_classification_atc.section_code,
classification_atc_section_texte = t_classification_atc.section_texte,
classification_atc_1_id = t_classification_atc.classification_atc_1_id,
classification_atc_1_code = t_classification_atc.classification_atc_1_code,
classification_atc_1_texte = t_classification_atc.classification_atc_1_texte,
classification_atc_2_id = t_classification_atc.classification_atc_2_id,
classification_atc_2_code = t_classification_atc.classification_atc_2_code,
classification_atc_2_texte = t_classification_atc.classification_atc_2_texte,
classification_atc_3_id = t_classification_atc.classification_atc_3_id,
classification_atc_3_code = t_classification_atc.classification_atc_3_code,
classification_atc_3_texte = t_classification_atc.classification_atc_3_texte,
classification_atc_4_id = t_classification_atc.classification_atc_4_id,
classification_atc_4_code = t_classification_atc.classification_atc_4_code,
classification_atc_4_texte = t_classification_atc.classification_atc_4_texte,
unite_stockage_code = t_unites_stockage.code,
unite_stockage_texte = t_unites_stockage.texte_court,
unite_stockage_section_id = t_unites_stockage.section_id,
unite_stockage_section_code = t_unites_stockage.section_code,
unite_stockage_section_texte = t_unites_stockage.section_texte,
unite_distribution_code = t_unites_distribution.code,
unite_distribution_texte = t_unites_distribution.texte_court,
unite_distribution_section_id = t_unites_distribution.section_id,
unite_distribution_section_code = t_unites_distribution.section_code,
unite_distribution_section_texte = t_unites_distribution.section_texte,
compte_code = t_compte.code,
compte_texte = t_compte.texte_court,
compte_section_id = t_compte.section_id,
compte_section_code = t_compte.section_code,
compte_section_texte = t_compte.section_texte
FROM eco.t_types_articles ,
eco.t_familles_articles,
eco.t_sous_familles_articles,
eco.t_categories_articles,
eco.t_sous_categories_articles,
eco.t_classification_atc,
eco.t_unites t_unites_stockage,
eco.t_unites t_unites_distribution,
eco.t_compte
WHERE type_id = t_types_articles.oid
AND famille_id = t_familles_articles.oid
AND sous_famille_id = t_sous_familles_articles.oid
AND categorie_id = t_categories_articles.oid
AND sous_categorie_id = t_sous_categories_articles.oid
AND classification_atc_id = t_classification_atc.oid
AND unite_stockage_id = t_unites_stockage.oid
AND unite_distribution_id = t_unites_distribution.oid
AND compte_id = t_compte.oid
AND (
type_code IS DISTINCT FROM t_types_articles.code OR
type_texte IS DISTINCT FROM t_types_articles.texte_court OR
type_section_id IS DISTINCT FROM t_types_articles.section_id OR
type_section_code IS DISTINCT FROM t_types_articles.section_code OR
type_section_texte IS DISTINCT FROM t_types_articles.section_texte OR
famille_code IS DISTINCT FROM t_familles_articles.code OR
famille_texte IS DISTINCT FROM t_familles_articles.texte_court OR
famille_section_id IS DISTINCT FROM t_familles_articles.section_id OR
famille_section_code IS DISTINCT FROM t_familles_articles.section_code OR
famille_section_texte IS DISTINCT FROM t_familles_articles.section_texte OR
sous_famille_code IS DISTINCT FROM t_sous_familles_articles.code OR
sous_famille_texte IS DISTINCT FROM t_sous_familles_articles.texte_court OR
sous_famille_section_id IS DISTINCT FROM t_sous_familles_articles.section_id OR
sous_famille_section_code IS DISTINCT FROM t_sous_familles_articles.section_code OR
sous_famille_section_texte IS DISTINCT FROM t_sous_familles_articles.section_texte OR
categorie_code IS DISTINCT FROM t_categories_articles.code OR
categorie_texte IS DISTINCT FROM t_categories_articles.texte_court OR
categorie_section_id IS DISTINCT FROM t_categories_articles.section_id OR
categorie_section_code IS DISTINCT FROM t_categories_articles.section_code OR
categorie_section_texte IS DISTINCT FROM t_categories_articles.section_texte OR
sous_categorie_code IS DISTINCT FROM t_sous_categories_articles.code OR
sous_categorie_texte IS DISTINCT FROM t_sous_categories_articles.texte_court OR
sous_categorie_section_id IS DISTINCT FROM t_sous_categories_articles.section_id OR
sous_categorie_section_code IS DISTINCT FROM t_sous_categories_articles.section_code OR
sous_categorie_section_texte IS DISTINCT FROM t_sous_categories_articles.section_texte OR
t_articles.classification_atc_code IS DISTINCT FROM t_classification_atc.code OR
t_articles.classification_atc_texte IS DISTINCT FROM t_classification_atc.texte_court OR
t_articles.classification_atc_section_id IS DISTINCT FROM t_classification_atc.section_id OR
t_articles.classification_atc_section_code IS DISTINCT FROM t_classification_atc.section_code OR
t_articles.classification_atc_section_texte IS DISTINCT FROM t_classification_atc.section_texte OR
t_articles.classification_atc_1_id IS DISTINCT FROM t_classification_atc.classification_atc_1_id OR
t_articles.classification_atc_1_code IS DISTINCT FROM t_classification_atc.classification_atc_1_code OR
t_articles.classification_atc_1_texte IS DISTINCT FROM t_classification_atc.classification_atc_1_texte OR
t_articles.classification_atc_2_id IS DISTINCT FROM t_classification_atc.classification_atc_2_id OR
t_articles.classification_atc_2_code IS DISTINCT FROM t_classification_atc.classification_atc_2_code OR
t_articles.classification_atc_2_texte IS DISTINCT FROM t_classification_atc.classification_atc_2_texte OR
t_articles.classification_atc_3_id IS DISTINCT FROM t_classification_atc.classification_atc_3_id OR
t_articles.classification_atc_3_code IS DISTINCT FROM t_classification_atc.classification_atc_3_code OR
t_articles.classification_atc_3_texte IS DISTINCT FROM t_classification_atc.classification_atc_3_texte OR
t_articles.classification_atc_4_id IS DISTINCT FROM t_classification_atc.classification_atc_4_id OR
t_articles.classification_atc_4_code IS DISTINCT FROM t_classification_atc.classification_atc_4_code OR
t_articles.classification_atc_4_texte IS DISTINCT FROM t_classification_atc.classification_atc_4_texte OR
t_articles.unite_stockage_code IS DISTINCT FROM t_unites_stockage.code OR
t_articles.unite_stockage_texte IS DISTINCT FROM t_unites_stockage.texte_court OR
t_articles.unite_stockage_section_id IS DISTINCT FROM t_unites_stockage.section_id OR
t_articles.unite_stockage_section_code IS DISTINCT FROM t_unites_stockage.section_code OR
t_articles.unite_stockage_section_texte IS DISTINCT FROM t_unites_stockage.section_texte OR
t_articles.unite_distribution_code IS DISTINCT FROM t_unites_distribution.code OR
t_articles.unite_distribution_texte IS DISTINCT FROM t_unites_distribution.texte_court OR
t_articles.unite_distribution_section_id IS DISTINCT FROM t_unites_distribution.section_id OR
t_articles.unite_distribution_section_code IS DISTINCT FROM t_unites_distribution.section_code OR
t_articles.unite_distribution_section_texte IS DISTINCT FROM t_unites_distribution.section_texte OR
t_articles.compte_code IS DISTINCT FROM t_compte.code OR
t_articles.compte_texte IS DISTINCT FROM t_compte.texte_court OR
t_articles.compte_section_id IS DISTINCT FROM t_compte.section_id OR
t_articles.compte_section_code IS DISTINCT FROM t_compte.section_code OR
t_articles.compte_section_texte IS DISTINCT FROM t_compte.section_texte
);
]]></sqlcmd>
</NODE>
<NODE label="Tables Fournisseurs">
<sqlcmd><![CDATA[
-- Types de fournisseurs
-- Fournisseurs (basé sur commandes)
INSERT INTO eco.t_fournisseurs(code_original, code, texte, texte_court)
SELECT TTIERS.OID, TTIERS.CODE, MAX(TTIERS.CAPTION), MAX(TTIERS.CAPTION)
FROM prod_sage100compta.TTIERS
WHERE TTIERS.OID IN
(
SELECT DISTINCT OIDTIERS
FROM prod_sage100compta.TPIECELIVRAISON
JOIN prod_sage100compta.TROLETIERS ON OIDROLETIERSRO = TROLETIERS.OID
UNION
SELECT DISTINCT OIDTIERS
FROM prod_sage100compta.TPIECETAXABLE
JOIN prod_sage100compta.TTYPEPIECEGC ON OIDTYPEPIECEGC = TTYPEPIECEGC.OID AND TTYPEPIECEGC.CODE = 'PA'
LEFT JOIN prod_sage100compta.TROLETIERS ON TPIECETAXABLE.OIDROLETIERSRO = TROLETIERS.OID
) AND
TTIERS.OID NOT IN (SELECT code_original FROM eco.t_fournisseurs WHERE code_original IS NOT NULL)
GROUP BY 1,2
ORDER BY 2
;
UPDATE eco.t_fournisseurs
SET code = TTIERS.CODE,
texte = TTIERS.CAPTION,
texte_court = TTIERS.CAPTION
FROM prod_sage100compta.TTIERS
WHERE code_original = TTIERS.OID
AND
(
t_fournisseurs.code IS DISTINCT FROM TTIERS.CODE OR
texte IS DISTINCT FROM TTIERS.CAPTION OR
texte_court IS DISTINCT FROM TTIERS.CAPTION
)
;
UPDATE eco.t_fournisseurs
SET type_id = 0
WHERE type_id IS DISTINCT FROM 0
;
UPDATE eco.t_fournisseurs SET
type_code = t_types_fournisseurs.code,
type_texte = t_types_fournisseurs.texte_court,
type_section_id = t_types_fournisseurs.section_id,
type_section_code = t_types_fournisseurs.section_code,
type_section_texte = t_types_fournisseurs.section_texte
FROM eco.t_types_fournisseurs
WHERE type_id = t_types_fournisseurs.oid
AND (
type_code IS DISTINCT FROM t_types_fournisseurs.code OR
type_texte IS DISTINCT FROM t_types_fournisseurs.texte_court OR
type_section_id IS DISTINCT FROM t_types_fournisseurs.section_id OR
type_section_code IS DISTINCT FROM t_types_fournisseurs.section_code OR
type_section_texte IS DISTINCT FROM t_types_fournisseurs.section_texte
);
UPDATE eco.t_articles SET
fournisseur_principal_id = t_fournisseurs.oid
FROM w_TPRODUIT TPRODUIT
JOIN eco.t_fournisseurs ON TPRODUIT.OIDTIERS = t_fournisseurs.code_original
WHERE t_articles.code_original = TPRODUIT.OID AND
fournisseur_principal_id IS DISTINCT FROM t_fournisseurs.oid
;
]]></sqlcmd>
</NODE>
<NODE label="Autres tables">
<sqlcmd><![CDATA[
-- Gestionnaires
-- Unités fonctionnelles
DROP TABLE IF EXISTS w_REFERENCE;
CREATE TEMP TABLE w_REFERENCE AS
SELECT
REFERENCE,
''::text AS code
FROM prod_sage100compta.TDETAILLIVRAISON
WHERE REFERENCE <> ''
GROUP BY 1;
UPDATE w_REFERENCE
SET code = upper(translate(REFERENCE,'éèôà-./°,.,''()?','eeoa '))
;
UPDATE w_REFERENCE
SET code = replace(code,' ',' ')
WHERE code LIKE '% %'
;
UPDATE w_REFERENCE
SET code = replace(code,' ',' ')
WHERE code LIKE '% %'
;
UPDATE w_REFERENCE
SET code = replace(code,' ',' ')
WHERE code LIKE '% %'
;
UPDATE w_REFERENCE
SET code =
substr(split_part(code,' ',1),1,5) ||
substr(split_part(code,' ',2),1,5)
WHERE split_part(code,' ',3) = ''
;
UPDATE w_REFERENCE
SET code =
substr(split_part(code,' ',1),1,2) ||
substr(split_part(code,' ',2),1,2) ||
substr(split_part(code,' ',3),1,2) ||
substr(split_part(code,' ',4),1,2) ||
substr(split_part(code,' ',5),1,2)
WHERE split_part(code,' ',3) <> ''
;
INSERT INTO eco.t_unites_fonctionnelles(code_original, code, texte, texte_court)
SELECT OID, CODE, CAPTION, CAPTION
FROM prod_sage100compta.TSITECOMMERCIALE
WHERE OID IN (SELECT OIDSITELIVRAISON FROM prod_sage100compta.TPIECELIVRAISON) AND
OID NOT IN (SELECT code_original FROM eco.t_unites_fonctionnelles WHERE code_original IS NOT NULL)
;
-- Lieux
-- Site
-- Types mouvements
INSERT INTO eco.t_types_mouvements(code_original, code, texte, texte_court)
SELECT TTYPEPIECEGC.OID, TTYPEPIECEGC.CODE, MAX(TTYPEPIECEGC.CAPTION), MAX(TTYPEPIECEGC.CAPTION)
FROM prod_sage100compta.TTYPEPIECEGC
WHERE TTYPEPIECEGC.OID IN
(
SELECT DISTINCT OIDTYPEPIECEGC
FROM prod_sage100compta.TPIECELIVRAISON
) AND
TTYPEPIECEGC.OID NOT IN (SELECT code_original FROM eco.t_types_mouvements WHERE code_original IS NOT NULL)
GROUP BY 1,2
ORDER BY 2
;
-- Types mouvements
INSERT INTO eco.t_types_mouvements(code_original, code, texte, texte_court)
SELECT TTYPEPIECEGC.OID, TTYPEPIECEGC.CODE, MAX(TTYPEPIECEGC.CAPTION), MAX(TTYPEPIECEGC.CAPTION)
FROM prod_sage100compta.TTYPEPIECEGC
WHERE TTYPEPIECEGC.OID IN
(
SELECT DISTINCT OIDTYPEPIECEGC
FROM prod_sage100compta.TPIECEINVENTAIRE
) AND
TTYPEPIECEGC.OID NOT IN (SELECT code_original FROM eco.t_types_mouvements WHERE code_original IS NOT NULL)
GROUP BY 1,2
ORDER BY 2
;
]]></sqlcmd>
</NODE>
</NODE>
<NODE name="PROD" label="RECUPERATION DES DONNEES DE PRODUCTION SAGE 100">
<NODE label="Commandes">
<sqlcmd><![CDATA[
SELECT base.cti_disable_index('eco', 'i_commandes_1');
SELECT base.cti_disable_index('eco', 'i_commandes_2');
SELECT base.cti_disable_index('eco', 'i_commandes_3');
SELECT base.cti_disable_index('eco', 'i_commandes_4');
SELECT base.cti_disable_index('eco', 'i_commandes_5');
SELECT base.cti_disable_index('eco', 'i_commandes_6');
SELECT base.cti_disable_index('eco', 'i_commandes_7');
SELECT base.cti_disable_index('eco', 'i_commandes_8');
INSERT INTO eco.p_commandes(
code_original,
numero,
date_commande,
date_engagement,
objet,
reference,
date_livraison_prevue,
etat_reception,
date_reception,
etat_liquidation,
fournisseur_id,
gestionnaire_id,
lieu_commande_id,
lieu_facturation_id,
lieu_livraison_id,
unite_fonctionnelle_id,
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
TPIECETAXABLE.OID AS code_original,
NOPIECE AS numero,
DATEPIECE AS date_commande,
DATEVALIDATION AS date_engagement,
''::text AS objet,
t_fournisseurs.texte AS reference,
DATELIVRAISON AS date_livraison_prevue,
'T' AS etat_reception,
'20991231'::date AS date_reception,
'T' AS etat_liquidation,
COALESCE(t_fournisseurs.oid, 0) AS fournisseur_id,
COALESCE(t_gestionnaires.oid,0) AS gestionnaire_id,
0::bigint AS lieu_commande_id,
COALESCE(t_lieux_facturation.oid,0) AS lieu_facturation_id,
COALESCE(t_lieux_facturation.oid,0) AS lieu_livraison_id,
0::bigint AS unite_fonctionnelle_id,
TOTALHT AS montant_commande_ht,
REMISEPIED AS montant_commande_remise,
TOTALTTC - TOTALHT AS montant_commande_tva,
0::numeric AS montant_commande_port,
TOTALTTC AS montant_commande_total,
0::numeric AS montant_liquidation_ht,
0::numeric AS montant_liquidation_remise,
0::numeric AS montant_liquidation_tva,
0::numeric AS montant_liquidation_port,
0::numeric AS montant_liquidation_total
FROM prod_sage100compta.TPIECETAXABLE
JOIN prod_sage100compta.TTYPEPIECEGC ON OIDTYPEPIECEGC = TTYPEPIECEGC.OID AND TTYPEPIECEGC.CODE = 'PA'
LEFT JOIN prod_sage100compta.TROLETIERS ON TPIECETAXABLE.OIDROLETIERSRO = TROLETIERS.OID
LEFT JOIN eco.t_fournisseurs ON TROLETIERS.OIDTIERS = t_fournisseurs.code_original
LEFT JOIN eco.t_lieux t_lieux_commande ON t_lieux_commande.code_original = 'XXXX'
LEFT JOIN eco.t_lieux t_lieux_livraison ON t_lieux_livraison.code_original = 'XXXX'
LEFT JOIN eco.t_lieux t_lieux_facturation ON t_lieux_facturation.code_original = 'XXXX'
LEFT JOIN eco.t_gestionnaires ON t_gestionnaires.code_original = 'XXXX'
WHERE DATEPIECE >= '[ENV_ECO_ANNEEDEBUT]-01-01'
ORDER BY 1;
SELECT base.cti_enable_index('eco', 'i_commandes_1');
SELECT base.cti_enable_index('eco', 'i_commandes_2');
SELECT base.cti_enable_index('eco', 'i_commandes_3');
SELECT base.cti_enable_index('eco', 'i_commandes_4');
SELECT base.cti_enable_index('eco', 'i_commandes_5');
SELECT base.cti_enable_index('eco', 'i_commandes_6');
SELECT base.cti_enable_index('eco', 'i_commandes_7');
SELECT base.cti_enable_index('eco', 'i_commandes_8');
SELECT base.cti_disable_index('eco', 'i_ligne_commandes_1');
SELECT base.cti_disable_index('eco', 'i_ligne_commandes_2');
SELECT base.cti_disable_index('eco', 'i_ligne_commandes_3');
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,
taux_prorata_tva)
SELECT
TDETAILTAXABLE.oid AS code_original,
p_commandes.oid AS commande_id,
TDETAILTAXABLE.NUMERO AS ligne_commande,
DESIGNATIONPRODUIT AS texte,
COALESCE(t_articles.oid, 0) AS article_id,
0::bigint AS unite_approvisionnement_id,
t_articles.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,
QUANTITETARIFEE AS quantite_approvisionnement,
PRIXNET AS prix_unitaire_approvisionnement,
0::numeric AS multiplicateur_stockage,
0::numeric AS quantite_stockage,
0::numeric AS prix_unitaire_stockage,
round(QUANTITETARIFEE::numeric * PRIXNET::numeric,2) AS montant_commande_ht,
0::numeric AS montant_commande_remise,
round(QUANTITETARIFEE::numeric * PRIXNET::numeric * TTAUXADATE.TAUX::numeric / 100,2) AS montant_commande_tva,
0::numeric AS montant_commande_port,
round(QUANTITETARIFEE::numeric * PRIXNET::numeric,2) +
round(QUANTITETARIFEE::numeric * PRIXNET::numeric * TTAUXADATE.TAUX::numeric / 100,2) AS montant_commande_ttc,
QUANTITETARIFEE AS quantite_livraison_approvisionnement,
QUANTITETARIFEE AS quantite_livraison_stockage,
round(QUANTITETARIFEE::numeric * PRIXNET::numeric,2) AS montant_livraison_ht,
round(QUANTITETARIFEE::numeric * PRIXNET::numeric,2) +
round(QUANTITETARIFEE::numeric * PRIXNET::numeric * TTAUXADATE.TAUX::numeric / 100,2) AS montant_livraison_ttc,
CASE WHEN STATUTLIVRAISON = 3 THEN 'T' WHEN STATUTLIVRAISON = 2 THEN 'S' WHEN STATUTLIVRAISON = 0 THEN 'N' ELSE 'P' END AS etat_livraison,
0::numeric AS montant_liquidation_ht,
0::numeric AS montant_liquidation_remise,
0::numeric AS montant_liquidation_tva,
0::numeric AS montant_liquidation_port,
0::numeric AS montant_liquidation_ttc,
'T',
0::numeric
FROM prod_sage100compta.TDETAILTAXABLE
JOIN eco.p_commandes ON TDETAILTAXABLE.OIDCONTRATCOMMERCIAL = p_commandes.code_original
JOIN (SELECT
oidmodetva, oidtva
FROM prod_sage100compta.TAPPLICATIONREGIMETVA
GROUP BY 1,2 ) TAPPLICATIONREGIMETVA ON TAPPLICATIONREGIMETVA.oidmodetva = TDETAILTAXABLE.oidmodetva
JOIN (SELECT
oidtva,
tdate,
(COALESCE (lead(tdate) OVER (PARTITION BY oidtva ORDER by tdate), '2099-12-31'))::date - interval '1 day' AS t_date_max,
taux
FROM
prod_sage100compta.TTAUXADATE)
TTAUXADATE ON TAPPLICATIONREGIMETVA.oidtva = TTAUXADATE.oidtva AND date_engagement between tdate and t_date_max
JOIN prod_sage100compta.TPRODUITCOMMERCIAL ON OIDPRODUITCOMMERCIAL = TPRODUITCOMMERCIAL.OID
LEFT JOIN eco.t_articles ON TPRODUITCOMMERCIAL.OIDPRODUIT = t_articles.code_original AND t_articles.oid != 0
LEFT JOIN base.t_ucd ON ucd_id = t_ucd.oid AND t_ucd.oid != 0
LEFT JOIN base.t_lpp ON lpp_id = t_lpp.oid AND t_lpp.oid != 0
LEFT JOIN eco.t_prorata_tva ON p_commandes.date_engagement BETWEEN t_prorata_tva.date_debut AND t_prorata_tva.date_fin
;
UPDATE eco.p_commandes SET
montant_commande_ht = subview.montant_commande_ht,
montant_commande_tva = subview.montant_commande_tva,
montant_commande_total = subview.montant_commande_ttc,
etat_reception = subview.etat_livraison
FROM
(
SELECT
commande_id,
SUM(p_lignes_commandes.montant_commande_ht) AS montant_commande_ht,
SUM(p_lignes_commandes.montant_commande_tva) AS montant_commande_tva,
SUM(p_lignes_commandes.montant_commande_ttc) AS montant_commande_ttc,
MIN(CASE WHEN etat_livraison NOT IN ('S','T') THEN 'N' ELSE 'T' END) AS etat_livraison
FROM eco.p_lignes_commandes
GROUP BY 1
) subview
WHERE commande_id = p_commandes.oid
;
SELECT base.cti_enable_index('eco', 'i_ligne_commandes_1');
SELECT base.cti_enable_index('eco', 'i_ligne_commandes_2');
SELECT base.cti_enable_index('eco', 'i_ligne_commandes_3');
]]></sqlcmd>
</NODE>
<NODE label="Mouvements">
<sqlcmd><![CDATA[
SELECT base.cti_disable_index('eco', 'i_mouvements_articles_1');
SELECT base.cti_disable_index('eco', 'i_mouvements_articles_2');
SELECT base.cti_disable_index('eco', 'i_mouvements_articles_3');
SELECT base.cti_disable_index('eco', 'i_mouvements_articles_4');
SELECT base.cti_disable_index('eco', 'i_mouvements_articles_5');
SELECT base.cti_disable_index('eco', 'i_mouvements_articles_6');
SELECT base.cti_disable_index('eco', 'i_mouvements_articles_7');
SELECT base.cti_disable_index('eco', 'i_mouvements_articles_8');
SELECT base.cti_disable_index('eco', 'i_mouvements_articles_9');
SELECT base.cti_disable_index('eco', 'i_mouvements_articles_10');
INSERT INTO eco.p_mouvements_articles(
date,
sens_mouvement,
type_mouvement_id,
texte,
gestionnaire_id,
lieu_id,
unite_fonctionnelle_id,
article_id,
compte_id,
fournisseur_id,
commande_id,
ligne_commande,
lpp_id,
ucd_id,
prix_unitaire,
entree_quantite,
entree_montant,
entree_montant_ht,
sortie_quantite,
sortie_montant,
sortie_montant_ht)
SELECT
DATE(TDETAILLIVRAISON.DATELIVRAISONPREVUE) AS date,
CASE WHEN TTYPEPIECEGC.CODE = 'PLA' THEN 'E' ELSE 'S' END AS sens_mouvement,
COALESCE(t_types_mouvements.oid,0) AS type_mouvement_id,
TPIECELIVRAISON.NOPIECE AS texte,
COALESCE(t_gestionnaires.oid,0) AS gestionnaire_id,
COALESCE(t_lieux.oid,0) AS lieu_id,
COALESCE(t_unites_fonctionnelles.oid,0) AS unite_fonctionnelle_id,
COALESCE(t_articles.oid,0) AS article_id,
COALESCE(t_articles.compte_id,0) AS compte_id,
COALESCE(t_fournisseurs.oid,t_articles.fournisseur_principal_id,0) AS fournisseur_id,
COALESCE(p_commandes.oid,0) AS commande_id,
COALESCE(p_lignes_commandes.ligne_commande,0) AS ligne_commande,
COALESCE(t_articles.lpp_id,0) AS lppid,
COALESCE(t_articles.ucd_id,0) AS ucd_id,
base.Cti_division(MONTANTNET, QUANTITE) AS prix_unitaire,
CASE WHEN TTYPEPIECEGC.CODE = 'PLA' THEN QUANTITE ELSE 0 END AS entree_quantite,
CASE WHEN TTYPEPIECEGC.CODE = 'PLA' THEN MONTANTNET ELSE 0 END * CASE WHEN DATE(TDETAILLIVRAISON.DATELIVRAISONPREVUE) >= '20140101' THEN taux_tva_1 ELSE taux_tva_2 END AS entree_montant,
CASE WHEN TTYPEPIECEGC.CODE = 'PLA' THEN MONTANTNET ELSE 0 END AS entree_montant_ht,
CASE WHEN TTYPEPIECEGC.CODE = 'PLV' THEN QUANTITE ELSE 0 END AS sortie_quantite,
CASE WHEN TTYPEPIECEGC.CODE = 'PLV' THEN MONTANTNET ELSE 0 END * CASE WHEN DATE(TDETAILLIVRAISON.DATELIVRAISONPREVUE) >= '20140101' THEN taux_tva_1 ELSE taux_tva_2 END AS sortie_montant,
CASE WHEN TTYPEPIECEGC.CODE = 'PLV' THEN MONTANTNET ELSE 0 END AS sortie_montant_ht
FROM prod_sage100compta.TDETAILLIVRAISON
JOIN prod_sage100compta.TPIECELIVRAISON ON TDETAILLIVRAISON.OIDPIECELIVRAISON = TPIECELIVRAISON.OID
JOIN prod_sage100compta.TPRODUITCOMMERCIAL ON OIDPRODUITCOMMERCIAL = TPRODUITCOMMERCIAL.OID
JOIN prod_sage100compta.TTYPEPIECEGC ON OIDTYPEPIECEGC = TTYPEPIECEGC.OID
JOIN w_TPRODUIT TPRODUIT ON TPRODUITCOMMERCIAL.OIDPRODUIT = TPRODUIT.OID
LEFT JOIN prod_sage100compta.TROLETIERS ON TPIECELIVRAISON.OIDROLETIERSRO = TROLETIERS.OID
LEFT JOIN eco.p_commandes ON p_commandes.oid = 0
LEFT JOIN eco.p_lignes_commandes ON p_lignes_commandes.oid = 0
LEFT JOIN eco.t_types_mouvements ON OIDTYPEPIECEGC = t_types_mouvements.code_original
LEFT JOIN eco.t_fournisseurs ON TROLETIERS.OIDTIERS = t_fournisseurs.code_original
LEFT JOIN eco.t_gestionnaires ON 'XXX' = t_gestionnaires.code_original
LEFT JOIN eco.t_lieux ON 'XXX' = t_lieux.code_original
LEFT JOIN eco.t_unites_fonctionnelles ON TPIECELIVRAISON.OIDSITELIVRAISON = t_unites_fonctionnelles.code_original
LEFT JOIN eco.t_articles ON TPRODUITCOMMERCIAL.OIDPRODUIT = t_articles.code_original AND t_articles.oid != 0
WHERE DATE(TDETAILLIVRAISON.DATELIVRAISONPREVUE) >= date('[ENV_ECO_ANNEEDEBUT]-01-01')
ORDER BY TDETAILLIVRAISON.DATELIVRAISONPREVUE
;
INSERT INTO eco.p_mouvements_articles(
date,
sens_mouvement,
type_mouvement_id,
texte,
gestionnaire_id,
lieu_id,
unite_fonctionnelle_id,
article_id,
compte_id,
fournisseur_id,
commande_id,
ligne_commande,
lpp_id,
ucd_id,
prix_unitaire,
entree_quantite,
entree_montant,
entree_montant_ht,
sortie_quantite,
sortie_montant,
sortie_montant_ht,
stock_quantite_debut,
stock_quantite_fin,
prix_unitaire_calcule
)
SELECT
DATE(DATEINVENTAIRE) AS date,
CASE WHEN ECART > 0 THEN 'E' ELSE 'S' END AS sens_mouvement,
COALESCE(t_types_mouvements.oid,0) AS type_mouvement_id,
TPIECEINVENTAIRE.NOPIECE AS texte,
COALESCE(t_gestionnaires.oid,0) AS gestionnaire_id,
COALESCE(t_lieux.oid,0) AS lieu_id,
COALESCE(t_unites_fonctionnelles.oid,0) AS unite_fonctionnelle_id,
COALESCE(t_articles.oid,0) AS article_id,
COALESCE(t_articles.compte_id,0) AS compte_id,
COALESCE(t_articles.fournisseur_principal_id,0) AS fournisseur_id,
COALESCE(p_commandes.oid,0) AS commande_id,
COALESCE(p_lignes_commandes.ligne_commande,0) AS ligne_commande,
COALESCE(t_articles.lpp_id,0) AS lppid,
COALESCE(t_articles.ucd_id,0) AS ucd_id,
PRIXUNITAIRE,
CASE WHEN ECART > 0 THEN ECART ELSE 0 END AS entree_quantite,
CASE WHEN ECART > 0 THEN MONTANTNET ELSE 0 END * CASE WHEN DATE(DATEINVENTAIRE) >= '20140101' THEN taux_tva_1 ELSE taux_tva_2 END AS entree_montant,
CASE WHEN ECART > 0 THEN MONTANTNET ELSE 0 END AS entree_montant_ht,
CASE WHEN ECART < 0 THEN ECART ELSE 0 END AS sortie_quantite,
CASE WHEN ECART < 0 THEN MONTANTNET ELSE 0 END * CASE WHEN DATE(DATEINVENTAIRE) >= '20140101' THEN taux_tva_1 ELSE taux_tva_2 END AS sortie_montant,
CASE WHEN ECART < 0 THEN MONTANTNET ELSE 0 END AS sortie_montant_ht,
QUANTITETHEORIQUE as stock_quantite_debut,
QUANTITEINVENTAIRE as stock_quantite_fin,
PRIXUNITAIRE as prix_unitaire_calcule
FROM prod_sage100compta.TDETAILINVENTAIRE
JOIN prod_sage100compta.TPIECEINVENTAIRE ON TDETAILINVENTAIRE.OIDPIECEINVENTAIRE = TPIECEINVENTAIRE.OID
JOIN prod_sage100compta.TTYPEPIECEGC ON OIDTYPEPIECEGC = TTYPEPIECEGC.OID
JOIN w_TPRODUIT TPRODUIT ON OIDPRODUITLOGISTIQUE = TPRODUIT.OIDPRODUITLIVRE
LEFT JOIN eco.p_commandes ON p_commandes.oid = 0
LEFT JOIN eco.p_lignes_commandes ON p_lignes_commandes.oid = 0
LEFT JOIN eco.t_types_mouvements ON OIDTYPEPIECEGC = t_types_mouvements.code_original
LEFT JOIN eco.t_gestionnaires ON 'XXX' = t_gestionnaires.code_original
LEFT JOIN eco.t_lieux ON 'XXX' = t_lieux.code_original
LEFT JOIN eco.t_unites_fonctionnelles ON 'XXX' = t_unites_fonctionnelles.code_original
LEFT JOIN eco.t_articles ON TPRODUIT.OID = t_articles.code_original AND t_articles.oid != 0
WHERE DATE(DATEINVENTAIRE) >= date('[ENV_ECO_ANNEEDEBUT]-01-01') AND VALIDE = 1
ORDER BY DATEINVENTAIRE
;
SELECT base.cti_enable_index('eco', 'i_mouvements_articles_1');
SELECT base.cti_enable_index('eco', 'i_mouvements_articles_2');
SELECT base.cti_enable_index('eco', 'i_mouvements_articles_3');
SELECT base.cti_enable_index('eco', 'i_mouvements_articles_4');
SELECT base.cti_enable_index('eco', 'i_mouvements_articles_5');
SELECT base.cti_enable_index('eco', 'i_mouvements_articles_6');
SELECT base.cti_enable_index('eco', 'i_mouvements_articles_7');
SELECT base.cti_enable_index('eco', 'i_mouvements_articles_8');
SELECT base.cti_enable_index('eco', 'i_mouvements_articles_9');
SELECT base.cti_enable_index('eco', 'i_mouvements_articles_10');
]]></sqlcmd>
</NODE>
<NODE label="Stocks">
<sqlcmd><![CDATA[
SELECT base.cti_disable_index('eco', 'i_stock_1');
SELECT base.cti_disable_index('eco', 'i_stock_2');
SELECT base.cti_disable_index('eco', 'i_stock_3');
SELECT base.cti_disable_index('eco', 'i_stock_4');
SELECT base.cti_disable_index('eco', 'i_stock_5');
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,
sortie_quantite,
sortie_montant,
stock_quantite_fin,
stock_valeur_fin,
pump)
SELECT
COALESCE(t_articles.oid,0) AS article_id,
date(date_trunc('month',DATEENTREE + interval '1 month') - interval '1 day') AS date_fin,
date(date_trunc('month',DATEENTREE)) AS date_debut,
COALESCE(t_articles.ucd_id,0) AS ucd_id,
COALESCE(t_articles.lpp_id,0) AS lpp_id,
COALESCE(t_articles.compte_id,0) AS compte_id,
COALESCE(t_lieux.oid,0) AS lieu_id,
0::bigint AS provider_id,
t_articles.fournisseur_principal_id AS fournisseur_id,
(MIN(ARRAY[DATEENTREE::text,STOCKINITIAL::text]))[2]::numeric AS stock_quantite_debut,
(MIN(ARRAY[DATEENTREE::text,PMPINITIAL::text]))[2]::numeric AS stock_valeur_debut,
SUM(QUANTITEENTREE) AS entree_quantite,
SUM(MONTANTENTREE) AS entree_montant,
SUM(QUANTITESORTIE) AS sortie_quantite,
SUM(QUANTITESORTIE*PMPINITIAL) AS sortie_montant,
(MAX(ARRAY[DATEENTREE::text,(STOCKINITIAL + QUANTITEENTREE - QUANTITESORTIE)::text]))[2]::numeric AS stock_quantite_fin,
(MAX(ARRAY[DATEENTREE::text,(STOCKINITIAL * PMPINITIAL + MONTANTENTREE - (QUANTITESORTIE*PMPINITIAL))::text]))[2]::numeric AS stock_valeur_fin,
(MAX(ARRAY[DATEENTREE::text,(base.cti_division(STOCKINITIAL * PMPINITIAL + MONTANTENTREE - (QUANTITESORTIE*PMPINITIAL),STOCKINITIAL + QUANTITEENTREE - QUANTITESORTIE))::text]))[2]::numeric
FROM prod_sage100compta.TPRODUITDEPOTDATE
LEFT JOIN eco.t_lieux ON 'XXX' = t_lieux.code_original
LEFT JOIN eco.t_unites_fonctionnelles ON 'XXX' = t_unites_fonctionnelles.code_original
LEFT JOIN w_TPRODUIT TPRODUIT ON OIDPRODUITLOGISTIQUE = TPRODUIT.OIDPRODUITLIVRE
LEFT JOIN eco.t_articles ON TPRODUIT.OID = t_articles.code_original AND t_articles.oid <> 0
GROUP BY 1,2,3,4,5,6,7,8,9
;
SELECT base.cti_enable_index('eco', 'i_stock_1');
SELECT base.cti_enable_index('eco', 'i_stock_2');
SELECT base.cti_enable_index('eco', 'i_stock_3');
SELECT base.cti_enable_index('eco', 'i_stock_4');
SELECT base.cti_enable_index('eco', 'i_stock_5');
SELECT eco.cti_update_mvt_qte_stock();
SELECT eco.cti_update_mvt_mnt_stock();
]]></sqlcmd>
</NODE>
<NODEx label="Factures">
<sqlcmd><![CDATA[
-- idem commandes avec typepiece 'PV'
SELECT base.cti_disable_index('eco', 'i_facture_1');
SELECT base.cti_disable_index('eco', 'i_facture_2');
SELECT base.cti_disable_index('eco', 'i_facture_3');
SELECT base.cti_disable_index('eco', 'i_facture_4');
SELECT base.cti_disable_index('eco', 'i_facture_5');
TRUNCATE eco.p_facture;
INSERT INTO eco.p_facture(
code_original,
no_facture,
commande_id,
date_facture,
date_reglement,
fournisseur_id,
texte,
montant_facture_article_ht,
montant_facture_article_ttc,
montant_facture_article_tva,
montant_facture_port_ht,
montant_facture_port_ttc,
montant_facture_port_tva,
montant_facture_ht,
montant_facture_ttc,
montant_facture_tva)
SELECT
PINVOICED.NUM_0 AS code_original,
CMMNUM_0 AS numero_facture,
p_commandes.oid,
date(BPRDATVCR_0) AS date_facture,
date(GACCENTRY.ACCDAT_0) AS date_reglement,
t_fournisseurs.oid,
'Facture n°' || CMMNUM_0 as texte,
SUM(AMTNOTLIN_0) AS montant_facture_article_ht,
SUM(AMTATILIN_0) AS montant_facture_article_ttc,
SUM(AMTTAXLIN1_0) AS montant_facture_article_tva,
0::numeric,
0::numeric,
0::numeric,
SUM(AMTNOTLIN_0) AS montant_facture_ht,
SUM(AMTATILIN_0) AS montant_facture_tt,
SUM(AMTTAXLIN1_0) AS montant_facture_tva
FROM prod_sagex3.PINVOICED
JOIN eco.p_commandes ON POHNUM_0= p_commandes.code_original
LEFT JOIN prod_sagex3.GACCENTRY ON GACCENTRY.NUM_0 = PINVOICED.NUM_0
LEFT JOIN eco.t_fournisseurs ON t_fournisseurs.code_original = BPR_0
WHERE PINVOICED.ACCDAT_0 >= '[ENV_ECO_ANNEEDEBUT]-01-01'
GROUP BY 1,2,3,4,5,6,7
ORDER BY 1;
SELECT base.cti_enable_index('eco', 'i_facture_1');
SELECT base.cti_enable_index('eco', 'i_facture_2');
SELECT base.cti_enable_index('eco', 'i_facture_3');
SELECT base.cti_enable_index('eco', 'i_facture_4');
SELECT base.cti_enable_index('eco', 'i_facture_5');
SELECT base.cti_disable_index('eco', 'i_lignes_facture_1');
SELECT base.cti_disable_index('eco', 'i_lignes_facture_2');
SELECT base.cti_disable_index('eco', 'i_lignes_facture_3');
SELECT base.cti_disable_index('eco', 'i_lignes_facture_4');
TRUNCATE eco.p_lignes_facture;
INSERT INTO eco.p_lignes_facture(
article_id,
code_original,
compte_id,
facture_id,
ligne_commande,
ligne_commande_id,
montant_facture_article_ht,
montant_facture_article_ttc,
montant_facture_article_tva,
montant_facture_port_ht,
montant_facture_port_ttc,
montant_facture_port_tva,
montant_facture_ht,
montant_facture_ttc,
montant_facture_tva
)
SELECT
t_articles.oid,
PINVOICED.NUM_0 || '-' || PINVOICED.PIDLIN_0 AS code_original,
0 as compte_id,
p_facture.oid,
ligne_commande,
p_lignes_commandes.oid,
AMTNOTLIN_0 AS montant_facture_article_ht,
AMTATILIN_0 AS montant_facture_article_ttc,
AMTTAXLIN1_0 AS montant_facture_article_tva,
0::numeric,
0::numeric,
0::numeric,
AMTNOTLIN_0 AS montant_facture_ht,
AMTATILIN_0 AS montant_facture_ttc,
AMTTAXLIN1_0 AS montant_facture_tva
FROM prod_sagex3.PINVOICED
JOIN eco.t_articles ON ITMREF_0 = t_articles.code_original
JOIN eco.p_facture ON NUM_0 = p_facture.code_original
JOIN eco.p_lignes_commandes ON POHNUM_0 || '-' || POPLIN_0 = p_lignes_commandes.code_original
LEFT JOIN prod_sagex3.GACCENTRY ON GACCENTRY.NUM_0 = PINVOICED.NUM_0
WHERE PINVOICED.ACCDAT_0 >= '[ENV_ECO_ANNEEDEBUT]-01-01'
ORDER BY 2;
SELECT base.cti_enable_index('eco', 'i_lignes_facture_1');
SELECT base.cti_enable_index('eco', 'i_lignes_facture_2');
SELECT base.cti_enable_index('eco', 'i_lignes_facture_3');
SELECT base.cti_enable_index('eco', 'i_lignes_facture_4');
]]></sqlcmd>
</NODEx>
</NODE>
</ROOT>