|
|
<?xml version="1.0" encoding="ISO-8859-1"?>
|
|
|
<ROOT>
|
|
|
|
|
|
<NODE name="INIT" label="INITIALISATIONS">
|
|
|
|
|
|
<NODE label="Détection Mois modifiés">
|
|
|
<sqlcmd><![CDATA[
|
|
|
|
|
|
DROP TABLE IF EXISTS w_GACCENTRYDA;
|
|
|
CREATE TEMP TABLE w_GACCENTRYDA AS
|
|
|
SELECT
|
|
|
GACCENTRYD.*,
|
|
|
GACCENTRYA.ANALIN_0,
|
|
|
GACCENTRYA.DIE_0,
|
|
|
GACCENTRYA.DIE_1,
|
|
|
GACCENTRYA.DIE_2,
|
|
|
GACCENTRYA.DIE_3,
|
|
|
GACCENTRYA.DIE_4,
|
|
|
GACCENTRYA.DIE_5,
|
|
|
GACCENTRYA.DIE_6,
|
|
|
GACCENTRYA.DIE_7,
|
|
|
GACCENTRYA.DIE_8,
|
|
|
GACCENTRYA.CCE_0,
|
|
|
GACCENTRYA.CCE_1,
|
|
|
GACCENTRYA.CCE_2,
|
|
|
GACCENTRYA.CCE_3,
|
|
|
GACCENTRYA.CCE_4,
|
|
|
GACCENTRYA.CCE_5,
|
|
|
GACCENTRYA.CCE_6,
|
|
|
GACCENTRYA.CCE_7,
|
|
|
GACCENTRYA.CCE_8,
|
|
|
GACCENTRYA.SNS_0 AS SNS_0_A,
|
|
|
GACCENTRYA.AMTCUR_0 AS AMTCUR_0_A,
|
|
|
GACCENTRYA.AMTLED_0 AS AMTLED_0_A
|
|
|
FROM prod_sagex3.GACCENTRYD
|
|
|
LEFT JOIN prod_sagex3.GACCENTRYA ON
|
|
|
GACCENTRYD.NUM_0 = GACCENTRYA.NUM_0 AND
|
|
|
GACCENTRYD.TYP_0 = GACCENTRYA.TYP_0 AND
|
|
|
GACCENTRYD.LIN_0 = GACCENTRYA.LIN_0
|
|
|
;
|
|
|
|
|
|
-- Suppression écritures avec compte inexistant (UO)
|
|
|
DELETE
|
|
|
FROM w_GACCENTRYDA
|
|
|
WHERE SUBSTR(ACC_0,1,1) NOT IN ('1','2','3','4','5','6','7','8','9')
|
|
|
;
|
|
|
|
|
|
UPDATE w_GACCENTRYDA
|
|
|
SET AMTCUR_0 = AMTLED_0
|
|
|
WHERE round(AMTCUR_0::numeric,2) <> round(AMTLED_0::numeric,2)
|
|
|
;
|
|
|
|
|
|
UPDATE w_GACCENTRYDA
|
|
|
SET AMTCUR_0_A = AMTLED_0_A
|
|
|
WHERE round(AMTCUR_0_A::numeric,2) <> round(AMTLED_0_A::numeric,2)
|
|
|
;
|
|
|
|
|
|
ANALYSE w_GACCENTRYDA
|
|
|
;
|
|
|
|
|
|
CREATE INDEX w_GACCENTRYDA_ik_num_0
|
|
|
ON w_GACCENTRYDA
|
|
|
USING btree
|
|
|
(num_0 COLLATE pg_catalog."default");
|
|
|
|
|
|
DROP TABLE IF EXISTS w_GACCENTRYD;
|
|
|
CREATE TEMP TABLE w_GACCENTRYD AS
|
|
|
SELECT to_char(PERIOD.PEREND_0, 'YYYYMM') AS MOIS,
|
|
|
GACCENTRYD.ACC_0,
|
|
|
Count(*) AS COUNT,
|
|
|
round(SUM(CASE WHEN GACCENTRY.CAT_0 = 1 AND COALESCE(GACCENTRYD.SNS_0_A,GACCENTRYD.SNS_0) > 0 THEN COALESCE(GACCENTRYD.AMTCUR_0_A,GACCENTRYD.AMTCUR_0) ELSE 0 END)::numeric,2) AS DEBIT,
|
|
|
round(SUM(CASE WHEN GACCENTRY.CAT_0 = 1 AND COALESCE(GACCENTRYD.SNS_0_A,GACCENTRYD.SNS_0) < 0 THEN COALESCE(GACCENTRYD.AMTCUR_0_A,GACCENTRYD.AMTCUR_0) ELSE 0 END)::numeric,2) AS CREDIT,
|
|
|
round(SUM(CASE WHEN GACCENTRY.CAT_0 = 2 AND COALESCE(GACCENTRYD.SNS_0_A,GACCENTRYD.SNS_0) > 0 THEN COALESCE(GACCENTRYD.AMTCUR_0_A,GACCENTRYD.AMTCUR_0) ELSE 0 END)::numeric,2) AS DEBIT_AJ,
|
|
|
round(SUM(CASE WHEN GACCENTRY.CAT_0 = 2 AND COALESCE(GACCENTRYD.SNS_0_A,GACCENTRYD.SNS_0) < 0 THEN COALESCE(GACCENTRYD.AMTCUR_0_A,GACCENTRYD.AMTCUR_0) ELSE 0 END)::numeric,2) AS CREDIT_AJ
|
|
|
FROM prod_sagex3.GACCENTRY
|
|
|
JOIN prod_sagex3.PERIOD ON GACCENTRY.CPY_0 = PERIOD.CPY_0 AND
|
|
|
GACCENTRY.FIY_0 = PERIOD.FIYNUM_0 AND
|
|
|
CASE WHEN GACCENTRY.PER_0 <> 0 THEN GACCENTRY.PER_0 ELSE 1 END = PERIOD.PERNUM_0 AND
|
|
|
PERIOD.PEREND_0 >= '[ENV_COMPTA_ANNEEDEBUT]1201' AND
|
|
|
PERIOD.LEDTYP_0 = 1
|
|
|
JOIN prod_sagex3.GTYPACCENT ON GACCENTRY.TYP_0 = GTYPACCENT.TYP_0 AND (GTYPACCENT.VCRREA_0 = 2 OR GACCENTRY.CAT_0 = 2)
|
|
|
JOIN prod_sagex3.GJOURNAL ON GACCENTRY.JOU_0 = GJOURNAL.JOU_0
|
|
|
JOIN w_GACCENTRYDA GACCENTRYD ON GACCENTRYD.NUM_0 = GACCENTRY.NUM_0 AND
|
|
|
GACCENTRYD.TYP_0 = GACCENTRY.TYP_0
|
|
|
WHERE GACCENTRY.CAT_0 IN (1,2) AND
|
|
|
(GACCENTRYD.LEDTYP_0 = 1 OR (AUZLED_0 = 1 AND AUZLED_1 = 2))
|
|
|
GROUP BY 1,2
|
|
|
ORDER BY 1,2;
|
|
|
|
|
|
DROP TABLE IF EXISTS w_historique_ecritures_total;
|
|
|
CREATE TEMP TABLE w_historique_ecritures_total AS
|
|
|
SELECT mois_comptable,
|
|
|
t_comptes.compte_nonsigne_numero as numero,
|
|
|
SUM(CASE WHEN ajustement = '0' THEN montant_debit ELSE 0 END) as debit,
|
|
|
SUM(CASE WHEN ajustement = '0' THEN montant_credit ELSE 0 END) as credit,
|
|
|
SUM(CASE WHEN ajustement IN ('2','3') THEN montant_debit ELSE 0 END) as debit_aj,
|
|
|
SUM(CASE WHEN ajustement IN ('2','3') THEN montant_credit ELSE 0 END) as credit_aj,
|
|
|
SUM(nombre_ecritures) as count
|
|
|
FROM compta.p_historique_ecritures_total, compta.t_comptes
|
|
|
WHERE mois_comptable >= [ENV_COMPTA_ANNEEDEBUT]01 AND
|
|
|
p_historique_ecritures_total.compte_id = t_comptes.oid AND
|
|
|
is_budget IS DISTINCT FROM '1'
|
|
|
GROUP BY 1,2
|
|
|
ORDER BY 1,2;
|
|
|
|
|
|
|
|
|
DROP TABLE IF EXISTS w_mois_modifies;
|
|
|
CREATE TEMP TABLE w_mois_modifies AS
|
|
|
SELECT w_GACCENTRYD.mois AS mois_modifie
|
|
|
FROM w_GACCENTRYD
|
|
|
LEFT JOIN w_historique_ecritures_total ON
|
|
|
w_historique_ecritures_total.mois_comptable = w_GACCENTRYD.mois AND
|
|
|
w_historique_ecritures_total.numero = w_GACCENTRYD.ACC_0
|
|
|
WHERE w_historique_ecritures_total.count IS DISTINCT FROM w_GACCENTRYD.count OR
|
|
|
w_historique_ecritures_total.debit IS DISTINCT FROM w_GACCENTRYD.debit OR
|
|
|
w_historique_ecritures_total.credit IS DISTINCT FROM w_GACCENTRYD.credit OR
|
|
|
w_historique_ecritures_total.debit_aj IS DISTINCT FROM w_GACCENTRYD.debit_aj OR
|
|
|
w_historique_ecritures_total.credit_aj IS DISTINCT FROM w_GACCENTRYD.credit_aj OR
|
|
|
w_historique_ecritures_total.mois_comptable >= [ENV_COMPTA_ANNEEDEBUT]01
|
|
|
GROUP BY 1;
|
|
|
|
|
|
ALTER TABLE w_mois_modifies ADD CONSTRAINT w_mois_modifies_pk PRIMARY KEY(mois_modifie);
|
|
|
|
|
|
|
|
|
|
|
|
CTISELECT_PROPERTY_READ 'MOISMODIFIES', COALESCE(base.cti_group_concat(mois_modifie),'0')
|
|
|
FROM w_mois_modifies;
|
|
|
|
|
|
|
|
|
echo Mois modifiés : [MOISMODIFIES];
|
|
|
|
|
|
-- Attribution du code partenaire (tiers) sur les lignes d'écritures d'une même pièce comptable/numéro/référence
|
|
|
-- Lignes d'écritures des partenaires
|
|
|
|
|
|
DROP TABLE IF EXISTS lignes_tiers
|
|
|
;
|
|
|
|
|
|
CREATE TEMP TABLE lignes_tiers AS
|
|
|
SELECT
|
|
|
num_0,
|
|
|
MAX(bpr_0) AS partenaire_code
|
|
|
FROM prod_sagex3.GACCENTRYD
|
|
|
WHERE bpr_0 <> ''
|
|
|
GROUP BY 1
|
|
|
;
|
|
|
|
|
|
-- Morceau de code temporaire pouvant être enlever à partir de Juin 2024
|
|
|
-- L'insertion en base de données ne s'effectue uniquement sur la détection d'un changement de montant pour un mois donné
|
|
|
-- A la prochaine détection d'un changement :
|
|
|
-- Correction de la mauvaise attribution du code partenaire sur toutes les écritures antérieures et actuelles
|
|
|
UPDATE compta.p_historique_ecritures
|
|
|
SET partenaire_id = subview.partenaire_id
|
|
|
FROM (
|
|
|
SELECT
|
|
|
lignes_tiers.num_0 AS identifiant_operation,
|
|
|
t_partenaires.oid AS partenaire_id
|
|
|
FROM lignes_tiers
|
|
|
JOIN compta.t_partenaires ON t_partenaires.code = lignes_tiers.partenaire_code
|
|
|
) AS subview
|
|
|
WHERE
|
|
|
p_historique_ecritures.identifiant_operation = subview.identifiant_operation
|
|
|
AND p_historique_ecritures.partenaire_id = 0
|
|
|
;
|
|
|
|
|
|
-- Les vues de l'application se base sur la table p_historique_ecritures_total se basant elle même sur p_historique_ecritures précédemment modifiée
|
|
|
UPDATE compta.p_historique_ecritures_total
|
|
|
SET partenaire_id = p_historique_ecritures.partenaire_id
|
|
|
FROM compta.p_historique_ecritures
|
|
|
WHERE
|
|
|
p_historique_ecritures_total.compte_id = p_historique_ecritures.compte_id
|
|
|
AND p_historique_ecritures_total.mois_comptable = p_historique_ecritures.mois_comptable
|
|
|
AND p_historique_ecritures_total.journal_id = p_historique_ecritures.journal_id
|
|
|
AND p_historique_ecritures_total.section_analytique_id = p_historique_ecritures.section_analytique_id
|
|
|
AND p_historique_ecritures_total.section_analytique_2_id = p_historique_ecritures.section_analytique_2_id
|
|
|
AND p_historique_ecritures_total.section_analytique_3_id = p_historique_ecritures.section_analytique_3_id
|
|
|
AND p_historique_ecritures_total.section_analytique_4_id = p_historique_ecritures.section_analytique_4_id
|
|
|
AND p_historique_ecritures_total.section_analytique_5_id = p_historique_ecritures.section_analytique_5_id
|
|
|
AND p_historique_ecritures_total.section_analytique_6_id = p_historique_ecritures.section_analytique_6_id
|
|
|
AND p_historique_ecritures_total.section_analytique_7_id = p_historique_ecritures.section_analytique_7_id
|
|
|
AND p_historique_ecritures_total.section_analytique_8_id = p_historique_ecritures.section_analytique_8_id
|
|
|
AND p_historique_ecritures_total.section_analytique_9_id = p_historique_ecritures.section_analytique_9_id
|
|
|
AND p_historique_ecritures_total.clinique_honoraire = p_historique_ecritures.clinique_honoraire
|
|
|
AND p_historique_ecritures_total.exercice_comptable = p_historique_ecritures.exercice_comptable
|
|
|
AND p_historique_ecritures_total.type_compta_id = p_historique_ecritures.type_compta_id
|
|
|
AND p_historique_ecritures_total.site_id = p_historique_ecritures.site_id
|
|
|
AND p_historique_ecritures_total.compte_extra_id = p_historique_ecritures.compte_extra_id
|
|
|
AND p_historique_ecritures_total.comptabilisee = p_historique_ecritures.comptabilisee
|
|
|
AND p_historique_ecritures_total.fin_exercice = p_historique_ecritures.fin_exercice
|
|
|
AND p_historique_ecritures_total.ajustement = p_historique_ecritures.ajustement
|
|
|
AND p_historique_ecritures_total.inter_site = p_historique_ecritures.inter_site
|
|
|
AND p_historique_ecritures_total.ecriture_consolidee = p_historique_ecritures.ecriture_consolidee
|
|
|
;
|
|
|
|
|
|
]]></sqlcmd>
|
|
|
</NODE>
|
|
|
|
|
|
|
|
|
|
|
|
</NODE>
|
|
|
|
|
|
<NODE name="ECRITURES" label="RECUPERATION ECRITURES">
|
|
|
<condition><![CDATA[
|
|
|
"[MOISMODIFIES]" != "0"
|
|
|
]]></condition>
|
|
|
|
|
|
<NODE label="Suppression avant regénération">
|
|
|
<sqlcmd><![CDATA[
|
|
|
|
|
|
SELECT base.cti_disable_index('compta', 'i_historique_ecritures_2');
|
|
|
SELECT base.cti_disable_index('compta', 'i_historique_ecritures_3');
|
|
|
SELECT base.cti_disable_index('compta', 'i_historique_ecritures_4');
|
|
|
SELECT base.cti_disable_index('compta', 'i_historique_ecritures_5');
|
|
|
SELECT base.cti_disable_index('compta', 'i_historique_ecritures_6');
|
|
|
SELECT base.cti_disable_index('compta', 'i_historique_ecritures_7');
|
|
|
SELECT base.cti_disable_index('compta', 'i_historique_ecritures_8');
|
|
|
SELECT base.cti_disable_index('compta', 'i_historique_ecritures_9');
|
|
|
SELECT base.cti_disable_index('compta', 'i_historique_ecritures_10');
|
|
|
SELECT base.cti_disable_index('compta', 'i_historique_ecritures_11');
|
|
|
SELECT base.cti_disable_index('compta', 'i_historique_ecritures_12');
|
|
|
SELECT base.cti_disable_index('compta', 'i_historique_ecritures_13');
|
|
|
|
|
|
|
|
|
DELETE FROM compta.p_historique_ecritures
|
|
|
USING w_mois_modifies
|
|
|
WHERE mois_comptable = mois_modifie AND
|
|
|
is_budget IS DISTINCT FROM '1';
|
|
|
|
|
|
SELECT base.cti_disable_index('compta', 'i_historique_ecritures_1');
|
|
|
|
|
|
|
|
|
|
|
|
SELECT base.cti_disable_index('compta', 'i_historique_ecritures_total_2');
|
|
|
SELECT base.cti_disable_index('compta', 'i_historique_ecritures_total_3');
|
|
|
SELECT base.cti_disable_index('compta', 'i_historique_ecritures_total_4');
|
|
|
SELECT base.cti_disable_index('compta', 'i_historique_ecritures_total_5');
|
|
|
SELECT base.cti_disable_index('compta', 'i_historique_ecritures_total_6');
|
|
|
SELECT base.cti_disable_index('compta', 'i_historique_ecritures_total_7');
|
|
|
SELECT base.cti_disable_index('compta', 'i_historique_ecritures_total_8');
|
|
|
SELECT base.cti_disable_index('compta', 'i_historique_ecritures_total_9');
|
|
|
SELECT base.cti_disable_index('compta', 'i_historique_ecritures_total_10');
|
|
|
SELECT base.cti_disable_index('compta', 'i_historique_ecritures_total_11');
|
|
|
SELECT base.cti_disable_index('compta', 'i_historique_ecritures_total_12');
|
|
|
SELECT base.cti_disable_index('compta', 'i_historique_ecritures_total_13');
|
|
|
|
|
|
DELETE FROM compta.p_historique_ecritures_total
|
|
|
USING w_mois_modifies
|
|
|
WHERE mois_comptable = mois_modifie AND
|
|
|
is_budget IS DISTINCT FROM '1';
|
|
|
|
|
|
SELECT base.cti_disable_index('compta', 'i_historique_ecritures_total_1');
|
|
|
|
|
|
|
|
|
|
|
|
]]></sqlcmd>
|
|
|
</NODE>
|
|
|
|
|
|
<NODE label="Génération détail">
|
|
|
<sqlcmd><![CDATA[
|
|
|
|
|
|
DROP TABLE IF EXISTS w_GACCENTRY;
|
|
|
CREATE TEMP TABLE w_GACCENTRY AS
|
|
|
SELECT
|
|
|
PERIOD.PEREND_0,
|
|
|
GACCENTRYD.NUM_0,
|
|
|
GACCENTRYD.TYP_0,
|
|
|
GACCENTRYD.LIN_0,
|
|
|
COALESCE(ANALIN_0,0) AS ANALIN_0,
|
|
|
GACCENTRYD.ACCDAT_0,
|
|
|
GACCENTRYD.DES_0,
|
|
|
GACCENTRYD.FCYLIN_0,
|
|
|
GACCENTRY.JOU_0,
|
|
|
GACCENTRY.CAT_0,
|
|
|
GACCENTRYD.LEDTYP_0,
|
|
|
GACCENTRYD.BPR_0,
|
|
|
GACCENTRYD.ACC_0,
|
|
|
GACCENTRYD.OFFACC_0,
|
|
|
REF_0,
|
|
|
BPRVCR_0,
|
|
|
BPRDATVCR_0,
|
|
|
COALESCE(CCE_0,'') AS CCE_0,
|
|
|
COALESCE(CCE_1,'') AS CCE_1,
|
|
|
COALESCE(CCE_2,'') AS CCE_2,
|
|
|
COALESCE(CCE_3,'') AS CCE_3,
|
|
|
COALESCE(CCE_4,'') AS CCE_4,
|
|
|
COALESCE(CCE_5,'') AS CCE_5,
|
|
|
COALESCE(CCE_6,'') AS CCE_6,
|
|
|
COALESCE(CCE_7,'') AS CCE_7,
|
|
|
COALESCE(CCE_8,'') AS CCE_8,
|
|
|
COALESCE(DIE_0,'') AS DIE_0,
|
|
|
COALESCE(DIE_1,'') AS DIE_1,
|
|
|
COALESCE(DIE_2,'') AS DIE_2,
|
|
|
COALESCE(DIE_3,'') AS DIE_3,
|
|
|
COALESCE(DIE_4,'') AS DIE_4,
|
|
|
COALESCE(DIE_5,'') AS DIE_5,
|
|
|
COALESCE(DIE_6,'') AS DIE_6,
|
|
|
COALESCE(DIE_7,'') AS DIE_7,
|
|
|
COALESCE(DIE_8,'') AS DIE_8,
|
|
|
round(CASE WHEN COALESCE(GACCENTRYD.SNS_0_A,GACCENTRYD.SNS_0) > 0 THEN COALESCE(GACCENTRYD.AMTCUR_0_A,GACCENTRYD.AMTCUR_0) ELSE 0 END::numeric,2) AS AMTCUR_debit,
|
|
|
round(CASE WHEN COALESCE(GACCENTRYD.SNS_0_A,GACCENTRYD.SNS_0) < 0 THEN COALESCE(GACCENTRYD.AMTCUR_0_A,GACCENTRYD.AMTCUR_0) ELSE 0 END::numeric,2) AS AMTCUR_credit,
|
|
|
GACCENTRYD.FCYLIN_0 || '|' ||
|
|
|
GACCENTRY.JOU_0 || '|' ||
|
|
|
GACCENTRYD.BPR_0 || '|' ||
|
|
|
GACCENTRYD.ACC_0 || '|' ||
|
|
|
COALESCE(CCE_0,'') || '|' ||
|
|
|
COALESCE(CCE_1,'') || '|' ||
|
|
|
COALESCE(CCE_2,'') || '|' ||
|
|
|
COALESCE(CCE_3,'') || '|' ||
|
|
|
COALESCE(CCE_4,'') || '|' ||
|
|
|
COALESCE(CCE_5,'') || '|' ||
|
|
|
COALESCE(CCE_6,'') || '|' ||
|
|
|
COALESCE(CCE_7,'') || '|' ||
|
|
|
COALESCE(CCE_8,'') || '|' ||
|
|
|
COALESCE(DIE_0,'') || '|' ||
|
|
|
COALESCE(DIE_1,'') || '|' ||
|
|
|
COALESCE(DIE_2,'') || '|' ||
|
|
|
COALESCE(DIE_3,'') || '|' ||
|
|
|
COALESCE(DIE_4,'') || '|' ||
|
|
|
COALESCE(DIE_5,'') || '|' ||
|
|
|
COALESCE(DIE_6,'') || '|' ||
|
|
|
COALESCE(DIE_7,'') || '|' ||
|
|
|
COALESCE(DIE_8,'') || '|' ||
|
|
|
GACCENTRYD.OFFACC_0 AS key
|
|
|
FROM prod_sagex3.GACCENTRY
|
|
|
JOIN prod_sagex3.PERIOD ON GACCENTRY.CPY_0 = PERIOD.CPY_0 AND
|
|
|
GACCENTRY.FIY_0 = PERIOD.FIYNUM_0 AND
|
|
|
CASE WHEN GACCENTRY.PER_0 <> 0 THEN GACCENTRY.PER_0 ELSE 1 END = PERIOD.PERNUM_0 AND
|
|
|
PERIOD.LEDTYP_0 = 1
|
|
|
JOIN w_mois_modifies ON mois_modifie = to_char(PERIOD.PEREND_0, 'YYYYMM')
|
|
|
JOIN prod_sagex3.GTYPACCENT ON GACCENTRY.TYP_0 = GTYPACCENT.TYP_0 AND (GTYPACCENT.VCRREA_0 = 2 OR GACCENTRY.CAT_0 = 2)
|
|
|
JOIN prod_sagex3.GJOURNAL ON GACCENTRY.JOU_0 = GJOURNAL.JOU_0
|
|
|
JOIN w_GACCENTRYDA GACCENTRYD ON GACCENTRYD.NUM_0 = GACCENTRY.NUM_0 AND
|
|
|
GACCENTRYD.TYP_0 = GACCENTRY.TYP_0
|
|
|
|
|
|
WHERE GACCENTRY.CAT_0 IN (1,2) AND
|
|
|
(GACCENTRYD.LEDTYP_0 = 1 OR (AUZLED_0 = 1 AND AUZLED_1 = 2))
|
|
|
ORDER BY GACCENTRYD.NUM_0, GACCENTRYD.TYP_0, GACCENTRYD.LIN_0;
|
|
|
|
|
|
|
|
|
DROP TABLE IF EXISTS w_GACCENTRY_keys;
|
|
|
CREATE TEMP TABLE w_GACCENTRY_keys AS
|
|
|
SELECT
|
|
|
key,
|
|
|
FCYLIN_0,
|
|
|
JOU_0,
|
|
|
BPR_0,
|
|
|
ACC_0,
|
|
|
CCE_0,
|
|
|
CCE_1,
|
|
|
CCE_2,
|
|
|
CCE_3,
|
|
|
CCE_4,
|
|
|
CCE_5,
|
|
|
CCE_6,
|
|
|
CCE_7,
|
|
|
CCE_8,
|
|
|
CCE_0 || CASE WHEN CCE_0 <> '' AND CCE_1 <> '' THEN '_' ELSE '' END || CCE_1 AS CCE,
|
|
|
DIE_0,
|
|
|
DIE_1,
|
|
|
DIE_2,
|
|
|
DIE_3,
|
|
|
DIE_4,
|
|
|
DIE_5,
|
|
|
DIE_6,
|
|
|
DIE_7,
|
|
|
DIE_8,
|
|
|
OFFACC_0,
|
|
|
0::bigint AS site_id,
|
|
|
0::bigint AS type_compta_id,
|
|
|
0::bigint AS compte_id,
|
|
|
'C'::text AS clinique_honoraire,
|
|
|
0::bigint AS journal_id,
|
|
|
0::bigint AS section_analytique_id,
|
|
|
0::bigint AS section_analytique_2_id,
|
|
|
0::bigint AS section_analytique_3_id,
|
|
|
0::bigint AS section_analytique_4_id,
|
|
|
0::bigint AS section_analytique_5_id,
|
|
|
0::bigint AS section_analytique_6_id,
|
|
|
0::bigint AS section_analytique_7_id,
|
|
|
0::bigint AS section_analytique_8_id,
|
|
|
0::bigint AS section_analytique_9_id,
|
|
|
0::bigint AS partenaire_id,
|
|
|
0::bigint AS compte_extra_id,
|
|
|
0::bigint AS compte_contrepartie_id
|
|
|
FROM w_GACCENTRY
|
|
|
GROUP BY 1,2,3,4,5,6,7,8,9,10,11,12,13,14,15,16,17,18,19,20,21,22,23,24,25;
|
|
|
|
|
|
UPDATE w_GACCENTRY_keys
|
|
|
SET site_id = t_sites.oid,
|
|
|
clinique_honoraire = t_sites.clinique_honoraire
|
|
|
FROM compta.t_sites
|
|
|
WHERE code_original = FCYLIN_0;
|
|
|
|
|
|
UPDATE w_GACCENTRY_keys
|
|
|
SET compte_id = t_comptes.oid,
|
|
|
compte_extra_id = t_comptes.oid,
|
|
|
type_compta_id = t_comptes.type_compta_id
|
|
|
FROM compta.t_comptes
|
|
|
WHERE numero = ACC_0;
|
|
|
|
|
|
UPDATE w_GACCENTRY_keys
|
|
|
SET journal_id = t_journaux.oid
|
|
|
FROM compta.t_journaux
|
|
|
WHERE code_original = JOU_0;
|
|
|
|
|
|
-- Sections analytiques concaténées
|
|
|
INSERT INTO compta.t_sections_analytiques(code, code_original, texte)
|
|
|
SELECT
|
|
|
CCE AS code,
|
|
|
CCE AS code_original,
|
|
|
MAX(COALESCE(CACCE_0.DES_0,w_GACCENTRY_keys.CCE_0) || CASE WHEN w_GACCENTRY_keys.CCE_0 <> '' AND w_GACCENTRY_keys.CCE_1 <> '' THEN ' - ' ELSE '' END || COALESCE(CACCE_1.DES_0,w_GACCENTRY_keys.CCE_1)) AS texte
|
|
|
FROM
|
|
|
w_GACCENTRY_keys
|
|
|
LEFT JOIN prod_sagex3.CACCE CACCE_0 ON w_GACCENTRY_keys.DIE_0 = CACCE_0.DIE_0 AND
|
|
|
w_GACCENTRY_keys.CCE_0 = CACCE_0.CCE_0
|
|
|
LEFT JOIN prod_sagex3.CACCE CACCE_1 ON w_GACCENTRY_keys.DIE_1 = CACCE_1.DIE_0 AND
|
|
|
w_GACCENTRY_keys.CCE_1 = CACCE_1.CCE_0
|
|
|
WHERE (SELECT valeur FROM compta.t_divers WHERE t_divers.code = 'X3SANA') IS DISTINCT FROM '1' AND
|
|
|
CCE <> '' AND
|
|
|
CCE NOT IN (SELECT code_original FROM compta.t_sections_analytiques WHERE code_original IS NOT NULL)
|
|
|
GROUP BY 1
|
|
|
ORDER BY 1;
|
|
|
|
|
|
UPDATE w_GACCENTRY_keys
|
|
|
SET section_analytique_id = t_sections_analytiques.oid
|
|
|
FROM compta.t_sections_analytiques
|
|
|
WHERE (SELECT valeur FROM compta.t_divers WHERE t_divers.code = 'X3SANA') IS DISTINCT FROM '1' AND
|
|
|
CCE <> '' AND code_original = CCE;
|
|
|
|
|
|
-- Sections analytiques non concaténées
|
|
|
INSERT INTO compta.t_sections_analytiques(code, code_original, texte)
|
|
|
SELECT
|
|
|
w_GACCENTRY_keys.CCE_0 AS code,
|
|
|
w_GACCENTRY_keys.CCE_0 AS code_original,
|
|
|
MAX(COALESCE(CACCE.DES_0,w_GACCENTRY_keys.CCE_0)) AS texte
|
|
|
FROM
|
|
|
w_GACCENTRY_keys
|
|
|
LEFT JOIN prod_sagex3.CACCE ON w_GACCENTRY_keys.DIE_0 = CACCE.DIE_0 AND
|
|
|
w_GACCENTRY_keys.CCE_0 = CACCE.CCE_0
|
|
|
WHERE (SELECT valeur FROM compta.t_divers WHERE t_divers.code = 'X3SANA') = '1' AND
|
|
|
w_GACCENTRY_keys.CCE_0 <> '' AND
|
|
|
w_GACCENTRY_keys.CCE_0 NOT IN (SELECT code_original FROM compta.t_sections_analytiques WHERE code_original IS NOT NULL)
|
|
|
GROUP BY 1
|
|
|
ORDER BY 1;
|
|
|
|
|
|
INSERT INTO compta.t_sections_analytiques(code, code_original, texte)
|
|
|
SELECT
|
|
|
w_GACCENTRY_keys.CCE_1 AS code,
|
|
|
w_GACCENTRY_keys.CCE_1 AS code_original,
|
|
|
MAX(COALESCE(CACCE.DES_0,w_GACCENTRY_keys.CCE_1)) AS texte
|
|
|
FROM
|
|
|
w_GACCENTRY_keys
|
|
|
LEFT JOIN prod_sagex3.CACCE ON w_GACCENTRY_keys.DIE_1 = CACCE.DIE_0 AND
|
|
|
w_GACCENTRY_keys.CCE_1 = CACCE.CCE_0
|
|
|
WHERE (SELECT valeur FROM compta.t_divers WHERE t_divers.code = 'X3SANA') = '1' AND
|
|
|
w_GACCENTRY_keys.CCE_1 <> '' AND
|
|
|
w_GACCENTRY_keys.CCE_1 NOT IN (SELECT code_original FROM compta.t_sections_analytiques WHERE code_original IS NOT NULL)
|
|
|
GROUP BY 1
|
|
|
ORDER BY 1;
|
|
|
|
|
|
INSERT INTO compta.t_sections_analytiques(code, code_original, texte)
|
|
|
SELECT
|
|
|
w_GACCENTRY_keys.CCE_2 AS code,
|
|
|
w_GACCENTRY_keys.CCE_2 AS code_original,
|
|
|
MAX(COALESCE(CACCE.DES_0,w_GACCENTRY_keys.CCE_2)) AS texte
|
|
|
FROM
|
|
|
w_GACCENTRY_keys
|
|
|
LEFT JOIN prod_sagex3.CACCE ON w_GACCENTRY_keys.DIE_2 = CACCE.DIE_0 AND
|
|
|
w_GACCENTRY_keys.CCE_2 = CACCE.CCE_0
|
|
|
WHERE (SELECT valeur FROM compta.t_divers WHERE t_divers.code = 'X3SANA') = '1' AND
|
|
|
w_GACCENTRY_keys.CCE_2 <> '' AND
|
|
|
w_GACCENTRY_keys.CCE_2 NOT IN (SELECT code_original FROM compta.t_sections_analytiques WHERE code_original IS NOT NULL)
|
|
|
GROUP BY 1
|
|
|
ORDER BY 1;
|
|
|
|
|
|
INSERT INTO compta.t_sections_analytiques(code, code_original, texte)
|
|
|
SELECT
|
|
|
w_GACCENTRY_keys.CCE_3 AS code,
|
|
|
w_GACCENTRY_keys.CCE_3 AS code_original,
|
|
|
MAX(COALESCE(CACCE.DES_0,w_GACCENTRY_keys.CCE_3)) AS texte
|
|
|
FROM
|
|
|
w_GACCENTRY_keys
|
|
|
LEFT JOIN prod_sagex3.CACCE ON w_GACCENTRY_keys.DIE_3 = CACCE.DIE_0 AND
|
|
|
w_GACCENTRY_keys.CCE_3 = CACCE.CCE_0
|
|
|
WHERE (SELECT valeur FROM compta.t_divers WHERE t_divers.code = 'X3SANA') = '1' AND
|
|
|
w_GACCENTRY_keys.CCE_3 <> '' AND
|
|
|
w_GACCENTRY_keys.CCE_3 NOT IN (SELECT code_original FROM compta.t_sections_analytiques WHERE code_original IS NOT NULL)
|
|
|
GROUP BY 1
|
|
|
ORDER BY 1;
|
|
|
|
|
|
|
|
|
INSERT INTO compta.t_sections_analytiques(code, code_original, texte)
|
|
|
SELECT
|
|
|
w_GACCENTRY_keys.CCE_4 AS code,
|
|
|
w_GACCENTRY_keys.CCE_4 AS code_original,
|
|
|
MAX(COALESCE(CACCE.DES_0,w_GACCENTRY_keys.CCE_4)) AS texte
|
|
|
FROM
|
|
|
w_GACCENTRY_keys
|
|
|
LEFT JOIN prod_sagex3.CACCE ON w_GACCENTRY_keys.DIE_4 = CACCE.DIE_0 AND
|
|
|
w_GACCENTRY_keys.CCE_4 = CACCE.CCE_0
|
|
|
WHERE (SELECT valeur FROM compta.t_divers WHERE t_divers.code = 'X3SANA') = '1' AND
|
|
|
w_GACCENTRY_keys.CCE_4 <> '' AND
|
|
|
w_GACCENTRY_keys.CCE_4 NOT IN (SELECT code_original FROM compta.t_sections_analytiques WHERE code_original IS NOT NULL)
|
|
|
GROUP BY 1
|
|
|
ORDER BY 1;
|
|
|
|
|
|
INSERT INTO compta.t_sections_analytiques(code, code_original, texte)
|
|
|
SELECT
|
|
|
w_GACCENTRY_keys.CCE_5 AS code,
|
|
|
w_GACCENTRY_keys.CCE_5 AS code_original,
|
|
|
MAX(COALESCE(CACCE.DES_0,w_GACCENTRY_keys.CCE_5)) AS texte
|
|
|
FROM
|
|
|
w_GACCENTRY_keys
|
|
|
LEFT JOIN prod_sagex3.CACCE ON w_GACCENTRY_keys.DIE_5 = CACCE.DIE_0 AND
|
|
|
w_GACCENTRY_keys.CCE_5 = CACCE.CCE_0
|
|
|
WHERE (SELECT valeur FROM compta.t_divers WHERE t_divers.code = 'X3SANA') = '1' AND
|
|
|
w_GACCENTRY_keys.CCE_5 <> '' AND
|
|
|
w_GACCENTRY_keys.CCE_5 NOT IN (SELECT code_original FROM compta.t_sections_analytiques WHERE code_original IS NOT NULL)
|
|
|
GROUP BY 1
|
|
|
ORDER BY 1;
|
|
|
|
|
|
INSERT INTO compta.t_sections_analytiques(code, code_original, texte)
|
|
|
SELECT
|
|
|
w_GACCENTRY_keys.CCE_6 AS code,
|
|
|
w_GACCENTRY_keys.CCE_6 AS code_original,
|
|
|
MAX(COALESCE(CACCE.DES_0,w_GACCENTRY_keys.CCE_6)) AS texte
|
|
|
FROM
|
|
|
w_GACCENTRY_keys
|
|
|
LEFT JOIN prod_sagex3.CACCE ON w_GACCENTRY_keys.DIE_6 = CACCE.DIE_0 AND
|
|
|
w_GACCENTRY_keys.CCE_6 = CACCE.CCE_0
|
|
|
WHERE (SELECT valeur FROM compta.t_divers WHERE t_divers.code = 'X3SANA') = '1' AND
|
|
|
w_GACCENTRY_keys.CCE_6 <> '' AND
|
|
|
w_GACCENTRY_keys.CCE_6 NOT IN (SELECT code_original FROM compta.t_sections_analytiques WHERE code_original IS NOT NULL)
|
|
|
GROUP BY 1
|
|
|
ORDER BY 1;
|
|
|
|
|
|
INSERT INTO compta.t_sections_analytiques(code, code_original, texte)
|
|
|
SELECT
|
|
|
w_GACCENTRY_keys.CCE_7 AS code,
|
|
|
w_GACCENTRY_keys.CCE_7 AS code_original,
|
|
|
MAX(COALESCE(CACCE.DES_0,w_GACCENTRY_keys.CCE_7)) AS texte
|
|
|
FROM
|
|
|
w_GACCENTRY_keys
|
|
|
LEFT JOIN prod_sagex3.CACCE ON w_GACCENTRY_keys.DIE_7 = CACCE.DIE_0 AND
|
|
|
w_GACCENTRY_keys.CCE_7 = CACCE.CCE_0
|
|
|
WHERE (SELECT valeur FROM compta.t_divers WHERE t_divers.code = 'X3SANA') = '1' AND
|
|
|
w_GACCENTRY_keys.CCE_7 <> '' AND
|
|
|
w_GACCENTRY_keys.CCE_7 NOT IN (SELECT code_original FROM compta.t_sections_analytiques WHERE code_original IS NOT NULL)
|
|
|
GROUP BY 1
|
|
|
ORDER BY 1;
|
|
|
|
|
|
INSERT INTO compta.t_sections_analytiques(code, code_original, texte)
|
|
|
SELECT
|
|
|
w_GACCENTRY_keys.CCE_8 AS code,
|
|
|
w_GACCENTRY_keys.CCE_8 AS code_original,
|
|
|
MAX(COALESCE(CACCE.DES_0,w_GACCENTRY_keys.CCE_8)) AS texte
|
|
|
FROM
|
|
|
w_GACCENTRY_keys
|
|
|
LEFT JOIN prod_sagex3.CACCE ON w_GACCENTRY_keys.DIE_8 = CACCE.DIE_0 AND
|
|
|
w_GACCENTRY_keys.CCE_8 = CACCE.CCE_0
|
|
|
WHERE (SELECT valeur FROM compta.t_divers WHERE t_divers.code = 'X3SANA') = '1' AND
|
|
|
w_GACCENTRY_keys.CCE_8 <> '' AND
|
|
|
w_GACCENTRY_keys.CCE_8 NOT IN (SELECT code_original FROM compta.t_sections_analytiques WHERE code_original IS NOT NULL)
|
|
|
GROUP BY 1
|
|
|
ORDER BY 1;
|
|
|
|
|
|
|
|
|
UPDATE w_GACCENTRY_keys
|
|
|
SET section_analytique_id = t_sections_analytiques.oid
|
|
|
FROM compta.t_sections_analytiques
|
|
|
WHERE (SELECT valeur FROM compta.t_divers WHERE t_divers.code = 'X3SANA') = '1' AND
|
|
|
CCE_0 <> '' AND code_original = CCE_0;
|
|
|
|
|
|
UPDATE w_GACCENTRY_keys
|
|
|
SET section_analytique_2_id = t_sections_analytiques.oid
|
|
|
FROM compta.t_sections_analytiques
|
|
|
WHERE (SELECT valeur FROM compta.t_divers WHERE t_divers.code = 'X3SANA') = '1' AND
|
|
|
CCE_1 <> '' AND code_original = CCE_1;
|
|
|
|
|
|
UPDATE w_GACCENTRY_keys
|
|
|
SET section_analytique_3_id = t_sections_analytiques.oid
|
|
|
FROM compta.t_sections_analytiques
|
|
|
WHERE (SELECT valeur FROM compta.t_divers WHERE t_divers.code = 'X3SANA') = '1' AND
|
|
|
CCE_2 <> '' AND code_original = CCE_2;
|
|
|
|
|
|
UPDATE w_GACCENTRY_keys
|
|
|
SET section_analytique_4_id = t_sections_analytiques.oid
|
|
|
FROM compta.t_sections_analytiques
|
|
|
WHERE (SELECT valeur FROM compta.t_divers WHERE t_divers.code = 'X3SANA') = '1' AND
|
|
|
CCE_3 <> '' AND code_original = CCE_3;
|
|
|
|
|
|
UPDATE w_GACCENTRY_keys
|
|
|
SET section_analytique_5_id = t_sections_analytiques.oid
|
|
|
FROM compta.t_sections_analytiques
|
|
|
WHERE (SELECT valeur FROM compta.t_divers WHERE t_divers.code = 'X3SANA') = '1' AND
|
|
|
CCE_4 <> '' AND code_original = CCE_4;
|
|
|
|
|
|
UPDATE w_GACCENTRY_keys
|
|
|
SET section_analytique_6_id = t_sections_analytiques.oid
|
|
|
FROM compta.t_sections_analytiques
|
|
|
WHERE (SELECT valeur FROM compta.t_divers WHERE t_divers.code = 'X3SANA') = '1' AND
|
|
|
CCE_5 <> '' AND code_original = CCE_5;
|
|
|
|
|
|
UPDATE w_GACCENTRY_keys
|
|
|
SET section_analytique_7_id = t_sections_analytiques.oid
|
|
|
FROM compta.t_sections_analytiques
|
|
|
WHERE (SELECT valeur FROM compta.t_divers WHERE t_divers.code = 'X3SANA') = '1' AND
|
|
|
CCE_6 <> '' AND code_original = CCE_6;
|
|
|
|
|
|
UPDATE w_GACCENTRY_keys
|
|
|
SET section_analytique_8_id = t_sections_analytiques.oid
|
|
|
FROM compta.t_sections_analytiques
|
|
|
WHERE (SELECT valeur FROM compta.t_divers WHERE t_divers.code = 'X3SANA') = '1' AND
|
|
|
CCE_7 <> '' AND code_original = CCE_7;
|
|
|
|
|
|
UPDATE w_GACCENTRY_keys
|
|
|
SET section_analytique_9_id = t_sections_analytiques.oid
|
|
|
FROM compta.t_sections_analytiques
|
|
|
WHERE (SELECT valeur FROM compta.t_divers WHERE t_divers.code = 'X3SANA') = '1' AND
|
|
|
CCE_8 <> '' AND code_original = CCE_8;
|
|
|
|
|
|
|
|
|
UPDATE w_GACCENTRY_keys
|
|
|
SET partenaire_id = t_partenaires.oid
|
|
|
FROM compta.t_partenaires
|
|
|
WHERE BPR_0 <> '' AND code_original = BPR_0;
|
|
|
|
|
|
UPDATE w_GACCENTRY_keys
|
|
|
SET compte_contrepartie_id = t_comptes.oid
|
|
|
FROM compta.t_comptes
|
|
|
WHERE OFFACC_0 <> '' AND numero = OFFACC_0 ;
|
|
|
|
|
|
|
|
|
UPDATE w_GACCENTRY_keys
|
|
|
SET compte_extra_id = t_comptes.oid,
|
|
|
type_compta_id = t_comptes.type_compta_id
|
|
|
FROM compta.t_comptes
|
|
|
WHERE w_GACCENTRY_keys.partenaire_id <> 0 AND
|
|
|
w_GACCENTRY_keys.compte_id = t_comptes.compte_general_id AND
|
|
|
w_GACCENTRY_keys.partenaire_id = t_comptes.partenaire_id;
|
|
|
|
|
|
|
|
|
ALTER TABLE w_GACCENTRY_keys ADD CONSTRAINT w_GACCENTRY_keys_pk PRIMARY KEY(key);
|
|
|
|
|
|
CREATE INDEX w_GACCENTRY_i1
|
|
|
ON w_GACCENTRY
|
|
|
USING btree
|
|
|
(key);
|
|
|
|
|
|
-- Attribution du code partenaire (tiers) sur les lignes d'écritures d'une même pièce comptable/numéro/référence
|
|
|
-- Lignes d'écritures des partenaires
|
|
|
|
|
|
UPDATE w_gaccentry_keys
|
|
|
SET partenaire_id = subview.partenaire_id
|
|
|
FROM
|
|
|
(
|
|
|
SELECT
|
|
|
w_gaccentry.key,
|
|
|
t_partenaires.oid AS partenaire_id
|
|
|
FROM lignes_tiers
|
|
|
JOIN w_gaccentry ON w_gaccentry.num_0 = lignes_tiers.num_0
|
|
|
JOIN compta.t_partenaires ON t_partenaires.code_original = lignes_tiers.partenaire_code
|
|
|
) AS subview
|
|
|
WHERE w_gaccentry_keys.key = subview.key
|
|
|
;
|
|
|
|
|
|
INSERT INTO compta.p_historique_ecritures
|
|
|
(site_id,
|
|
|
type_compta_id,
|
|
|
compte_id,
|
|
|
date_ecriture,
|
|
|
exercice_comptable,
|
|
|
mois_comptable,
|
|
|
clinique_honoraire,
|
|
|
journal_id,
|
|
|
section_analytique_id,
|
|
|
section_analytique_2_id,
|
|
|
section_analytique_3_id,
|
|
|
section_analytique_4_id,
|
|
|
section_analytique_5_id,
|
|
|
section_analytique_6_id,
|
|
|
section_analytique_7_id,
|
|
|
section_analytique_8_id,
|
|
|
section_analytique_9_id,
|
|
|
partenaire_id,
|
|
|
compte_extra_id,
|
|
|
comptabilisee,
|
|
|
fin_exercice,
|
|
|
ajustement,
|
|
|
inter_site,
|
|
|
cle_originale,
|
|
|
identifiant_operation,
|
|
|
compte_contrepartie_id,
|
|
|
texte,
|
|
|
date_facture_fournisseur,
|
|
|
piece,
|
|
|
dossier,
|
|
|
date_echeance,
|
|
|
journal_paiement_id,
|
|
|
mode_paiement_id,
|
|
|
numero_cheque,
|
|
|
montant_credit,
|
|
|
montant_debit)
|
|
|
SELECT
|
|
|
site_id,
|
|
|
type_compta_id,
|
|
|
compte_id,
|
|
|
date(ACCDAT_0) AS date_ecriture,
|
|
|
date_part('year',PEREND_0) AS exercice_comptable,
|
|
|
to_number(to_char(PEREND_0, 'YYYYMM'),'000000') AS mois_comptable,
|
|
|
clinique_honoraire,
|
|
|
journal_id,
|
|
|
section_analytique_id,
|
|
|
section_analytique_2_id,
|
|
|
section_analytique_3_id,
|
|
|
section_analytique_4_id,
|
|
|
section_analytique_5_id,
|
|
|
section_analytique_6_id,
|
|
|
section_analytique_7_id,
|
|
|
section_analytique_8_id,
|
|
|
section_analytique_9_id,
|
|
|
partenaire_id,
|
|
|
compte_extra_id,
|
|
|
'1'::text AS comptabilisee,
|
|
|
'0'::text AS fin_exercice,
|
|
|
CASE
|
|
|
WHEN t_divers.valeur = '1' THEN
|
|
|
CASE
|
|
|
WHEN CAT_0 = '5' THEN '3'
|
|
|
ELSE '0'::text
|
|
|
END
|
|
|
ELSE
|
|
|
CASE
|
|
|
WHEN CAT_0 = 2 THEN '3'
|
|
|
WHEN TYP_0 = 'ODM' THEN '3'
|
|
|
WHEN LEDTYP_0 = 1 THEN '0'::text
|
|
|
ELSE '2'::text
|
|
|
END
|
|
|
END AS ajustement,
|
|
|
'0'::text AS inter_site,
|
|
|
TYP_0 || '-' || NUM_0 || '-' || to_char(LIN_0,'FM00000') || CASE WHEN COALESCE(ANALIN_0,0) > 1 THEN '-' || to_char(ANALIN_0,'FM00000') ELSE '' END AS cle_originale,
|
|
|
NUM_0 AS identifiant_operation,
|
|
|
compte_contrepartie_id,
|
|
|
substr(DES_0,1,100) AS texte,
|
|
|
date(COALESCE(CASE WHEN BPRDATVCR_0 > '[ENV_COMPTA_ANNEEDEBUT]0101' THEN BPRDATVCR_0 ELSE NULL END,'20991231')) AS date_facture_fournisseur,
|
|
|
substr(REF_0,1,255) AS texte,
|
|
|
substr(BPRVCR_0,1,255) AS dossier,
|
|
|
'20991231'::date AS date_echeance,
|
|
|
0::bigint AS journal_paiement_id,
|
|
|
0::bigint AS mode_paiement_id,
|
|
|
''::text AS numero_cheque,
|
|
|
AMTCUR_credit,
|
|
|
AMTCUR_debit
|
|
|
FROM w_GACCENTRY
|
|
|
JOIN w_GACCENTRY_keys ON w_GACCENTRY_keys.key = w_GACCENTRY.key
|
|
|
JOIN compta.t_divers ON t_divers.code = 'X3AJUS'
|
|
|
ORDER BY NUM_0, TYP_0, LIN_0;
|
|
|
|
|
|
|
|
|
SELECT base.cti_enable_index('compta', 'i_historique_ecritures_1');
|
|
|
SELECT base.cti_enable_index('compta', 'i_historique_ecritures_2');
|
|
|
SELECT base.cti_enable_index('compta', 'i_historique_ecritures_3');
|
|
|
SELECT base.cti_enable_index('compta', 'i_historique_ecritures_4');
|
|
|
SELECT base.cti_enable_index('compta', 'i_historique_ecritures_5');
|
|
|
SELECT base.cti_enable_index('compta', 'i_historique_ecritures_6');
|
|
|
SELECT base.cti_enable_index('compta', 'i_historique_ecritures_7');
|
|
|
SELECT base.cti_enable_index('compta', 'i_historique_ecritures_8');
|
|
|
SELECT base.cti_enable_index('compta', 'i_historique_ecritures_9');
|
|
|
SELECT base.cti_enable_index('compta', 'i_historique_ecritures_10');
|
|
|
SELECT base.cti_enable_index('compta', 'i_historique_ecritures_11');
|
|
|
SELECT base.cti_enable_index('compta', 'i_historique_ecritures_12');
|
|
|
SELECT base.cti_enable_index('compta', 'i_historique_ecritures_13');
|
|
|
|
|
|
|
|
|
|
|
|
]]></sqlcmd>
|
|
|
</NODE>
|
|
|
|
|
|
</NODE>
|
|
|
|
|
|
<NODE name="POST" label="TRAITEMENTS COMPLEMENTAIRES COMMUNS">
|
|
|
|
|
|
<condition><![CDATA[
|
|
|
"[MOISMODIFIES]" != "0"
|
|
|
]]></condition>
|
|
|
|
|
|
<NODE label="Comptabilité extra-comptable">
|
|
|
<sqlcmd><![CDATA[
|
|
|
|
|
|
-- Mise a jour type auxiliaire si différent du paramétrage du compte collectif
|
|
|
UPDATE compta.t_comptes t_comptes_auxiliaires
|
|
|
SET type_compta_id = t_comptes.type_compta_extra_id
|
|
|
FROM compta.t_comptes
|
|
|
WHERE t_comptes_auxiliaires.compte_general_id = t_comptes.oid AND
|
|
|
t_comptes_auxiliaires.compte_general_id <> t_comptes_auxiliaires.oid AND
|
|
|
t_comptes_auxiliaires.type_compta_id <> t_comptes.type_compta_extra_id
|
|
|
;
|
|
|
|
|
|
-- Determination des comptes collectifs selon ecritures
|
|
|
DROP TABLE IF EXISTS w_comptes_collectifs;
|
|
|
CREATE TEMP TABLE w_comptes_collectifs AS
|
|
|
SELECT compte_nonsigne_id AS compte_id
|
|
|
FROM compta.p_historique_ecritures
|
|
|
JOIN compta.t_comptes ON p_historique_ecritures.compte_id = t_comptes.oid
|
|
|
WHERE p_historique_ecritures.partenaire_id <> 0
|
|
|
group by 1
|
|
|
HAVING count(DISTINCT p_historique_ecritures.partenaire_id) > 1
|
|
|
ORDER BY 1;
|
|
|
|
|
|
UPDATE compta.t_comptes
|
|
|
SET collectif = '1',
|
|
|
type_compta_extra_id = CASE WHEN type_compta_extra_id = 0 THEN type_compta_id ELSE type_compta_extra_id END,
|
|
|
numero_extra = numero || '-*',
|
|
|
texte_extra = texte || ' (*)'
|
|
|
FROm w_comptes_collectifs
|
|
|
WHERE w_comptes_collectifs.compte_id = t_comptes.oid AND
|
|
|
collectif IS DISTINCT FROM '1';
|
|
|
|
|
|
DELETE FROM compta.t_comptes
|
|
|
WHERE compte_general_id <> oid AND
|
|
|
compte_general_id IN (SELECT oid FROM compta.t_comptes WHERE collectif <> '1' OR type_compta_extra_id = 0);
|
|
|
|
|
|
DROP TABLE IF EXISTS w_comptes_extra;
|
|
|
CREATE TEMP TABLE w_comptes_extra AS
|
|
|
SELECT t_comptes_nonsigne.type_compta_extra_id AS type_compta_id,
|
|
|
replace(t_comptes_nonsigne.numero_extra, '*', t_partenaires.code) AS numero,
|
|
|
replace(t_comptes_nonsigne.texte_extra, '*', t_partenaires.texte_court) AS texte,
|
|
|
t_comptes.compte_nonsigne_id AS compte_general_id,
|
|
|
t_comptes_nonsigne.clinique_honoraire,
|
|
|
p_historique_ecritures.partenaire_id
|
|
|
FROM compta.p_historique_ecritures
|
|
|
JOIN compta.t_partenaires ON p_historique_ecritures.partenaire_id = t_partenaires.oid AND
|
|
|
p_historique_ecritures.partenaire_id <> 0
|
|
|
JOIN compta.t_comptes ON compte_id = t_comptes.oid
|
|
|
JOIN compta.t_comptes t_comptes_nonsigne ON t_comptes.compte_nonsigne_id = t_comptes_nonsigne.oid AND t_comptes_nonsigne.collectif = '1'
|
|
|
GROUP BY 1,2,3,4,5,6;
|
|
|
|
|
|
UPDATE compta.t_comptes
|
|
|
SET numero = w_comptes_extra.numero, texte = substr(w_comptes_extra.texte,1,50)
|
|
|
FROM w_comptes_extra
|
|
|
WHERE t_comptes.type_compta_id = w_comptes_extra.type_compta_id AND
|
|
|
t_comptes.compte_general_id = w_comptes_extra.compte_general_id AND
|
|
|
t_comptes.partenaire_id = w_comptes_extra.partenaire_id AND
|
|
|
t_comptes.partenaire_id <> 0 AND
|
|
|
(
|
|
|
t_comptes.numero IS DISTINCT FROM w_comptes_extra.numero OR
|
|
|
t_comptes.texte IS DISTINCT FROM substr(w_comptes_extra.texte,1,50)
|
|
|
);
|
|
|
|
|
|
INSERT INTO compta.t_comptes(
|
|
|
type_compta_id, numero, texte,
|
|
|
compte_general_id, clinique_honoraire,
|
|
|
banque, etat, classe_1_id, classe_2_id, classe_3_id, classe_4_id, classe_5_id, classe_6_id,
|
|
|
solde_initial, collectif, type_compta_extra_id, numero_extra, texte_extra, partenaire_id)
|
|
|
SELECT type_compta_id, numero, substr(texte,1,50),
|
|
|
compte_general_id, clinique_honoraire, '0', '', 0, 0, 0, 0, 0, 0,
|
|
|
0, '0', 0, '', '', partenaire_id
|
|
|
FROM w_comptes_extra
|
|
|
WHERE partenaire_id <> 0 AND
|
|
|
type_compta_id || '.' || compte_general_id || '.' || partenaire_id
|
|
|
NOT IN (SELECT type_compta_id || '.' || t_comptes.compte_general_id || '.' || partenaire_id FROM compta.t_comptes);
|
|
|
|
|
|
|
|
|
|
|
|
-- Mise à jour des ecritures comptables
|
|
|
|
|
|
DROP TABLE IF EXISTS w_comptes_extra;
|
|
|
CREATE TEMP TABLE w_comptes_extra AS
|
|
|
SELECT t_comptes.oid AS compte_id, t_comptes_extra.oid AS compte_extra_id, t_comptes_extra.partenaire_id
|
|
|
FROM compta.t_comptes, compta.t_comptes t_comptes_extra
|
|
|
WHERE t_comptes_extra.type_compta_id = t_comptes.type_compta_extra_id
|
|
|
AND t_comptes.collectif = '1'
|
|
|
AND t_comptes.type_compta_extra_id > 0
|
|
|
AND t_comptes_extra.compte_general_id = t_comptes.oid;
|
|
|
|
|
|
CREATE INDEX w_comptes_extra_i1 ON w_comptes_extra USING btree (compte_id);
|
|
|
CREATE INDEX w_comptes_extra_i2 ON w_comptes_extra USING btree (partenaire_id);
|
|
|
|
|
|
|
|
|
UPDATE compta.p_historique_ecritures SET compte_extra_id = compte_id
|
|
|
WHERE compte_extra_id <> compte_id AND
|
|
|
compte_id IN (SELECT oid FROM compta.t_comptes WHERE collectif <> '1' OR type_compta_extra_id = 0);
|
|
|
|
|
|
DROP TABLE IF EXISTS w_historique_ecritures_update;
|
|
|
CREATE TEMP TABLE w_historique_ecritures_update(compte_id bigint, partenaire_id bigint, to_compte_extra_id bigint);
|
|
|
|
|
|
CREATE INDEX w_historique_ecritures_update_i1 ON w_historique_ecritures_update USING btree (compte_id);
|
|
|
CREATE INDEX w_historique_ecritures_update_i2 ON w_historique_ecritures_update USING btree (partenaire_id);
|
|
|
|
|
|
SELECT base.cti_execute(
|
|
|
'TRUNCATE w_historique_ecritures_update.,
|
|
|
INSERT INTO w_historique_ecritures_update
|
|
|
SELECT p_historique_ecritures.compte_id, p_historique_ecritures.partenaire_id, w_comptes_extra.compte_extra_id
|
|
|
FROM compta.p_historique_ecritures
|
|
|
JOIN compta.t_comptes ON p_historique_ecritures.compte_id = t_comptes.oid
|
|
|
JOIN w_comptes_extra ON t_comptes.compte_nonsigne_id = w_comptes_extra.compte_id AND
|
|
|
p_historique_ecritures.partenaire_id = w_comptes_extra.partenaire_id
|
|
|
WHERE p_historique_ecritures.partenaire_id <> 0 AND
|
|
|
p_historique_ecritures.compte_extra_id IS DISTINCT FROM w_comptes_extra.compte_extra_id
|
|
|
GROUP BY 1,2,3
|
|
|
LIMIT 50.,
|
|
|
|
|
|
UPDATE compta.p_historique_ecritures
|
|
|
SET compte_extra_id = w_historique_ecritures_update.to_compte_extra_id
|
|
|
FROM w_historique_ecritures_update
|
|
|
WHERE p_historique_ecritures.partenaire_id <> 0 AND
|
|
|
p_historique_ecritures.compte_id = w_historique_ecritures_update.compte_id AND
|
|
|
p_historique_ecritures.partenaire_id = w_historique_ecritures_update.partenaire_id AND
|
|
|
p_historique_ecritures.compte_extra_id IS DISTINCT FROM w_historique_ecritures_update.to_compte_extra_id'
|
|
|
,
|
|
|
2000
|
|
|
);
|
|
|
|
|
|
|
|
|
|
|
|
]]></sqlcmd>
|
|
|
|
|
|
</NODE>
|
|
|
|
|
|
|
|
|
<NODE label="Compléments écritures">
|
|
|
|
|
|
<sqlcmd><![CDATA[
|
|
|
|
|
|
UPDATE compta.p_historique_ecritures
|
|
|
SET clinique_honoraire = 'C'
|
|
|
FROM compta.t_sites
|
|
|
WHERE p_historique_ecritures.site_id = t_sites.oid
|
|
|
AND p_historique_ecritures.clinique_honoraire <> 'C'
|
|
|
AND site_id IN (SELECT oid FROM compta.t_sites WHERE clinique_honoraire <> 'H');
|
|
|
|
|
|
|
|
|
UPDATE compta.p_historique_ecritures
|
|
|
SET clinique_honoraire = 'H'
|
|
|
FROM compta.t_sites
|
|
|
WHERE p_historique_ecritures.site_id = t_sites.oid
|
|
|
AND p_historique_ecritures.clinique_honoraire <> 'H'
|
|
|
AND site_id IN (SELECT oid FROM compta.t_sites WHERE clinique_honoraire = 'H');
|
|
|
|
|
|
|
|
|
UPDATE compta.p_historique_ecritures
|
|
|
SET compte_id = t_comptes.compte_general_id
|
|
|
FROM compta.t_comptes
|
|
|
WHERE comptabilisee <> '1'
|
|
|
AND compte_id = t_comptes.oid
|
|
|
AND t_comptes.oid <> t_comptes.compte_general_id
|
|
|
AND compte_id = compte_extra_id;
|
|
|
|
|
|
|
|
|
|
|
|
]]></sqlcmd>
|
|
|
|
|
|
</NODE>
|
|
|
|
|
|
|
|
|
<NODE label="Regroupements sections analytiques">
|
|
|
|
|
|
<sqlcmd><![CDATA[
|
|
|
|
|
|
INSERT INTO compta.t_classes(
|
|
|
code, texte, table_id, is_cti, sequence)
|
|
|
SELECT 'ANA1', 'Lieu de rattachement', t_listes_tables.oid, '1', 1
|
|
|
FROM compta.t_listes_tables
|
|
|
WHERE (SELECT valeur FROM compta.t_divers WHERE t_divers.code = 'X3SANA') IS DISTINCT FROM '1' AND
|
|
|
t_listes_tables.code = 'ANA' AND
|
|
|
(SELECT t_classes.oid
|
|
|
FROM compta.t_classes
|
|
|
JOIN compta.t_listes_tables ON table_id = t_listes_tables.oid
|
|
|
WHERE t_listes_tables.code = 'ANA' AND
|
|
|
sequence = 1) IS NULL;
|
|
|
|
|
|
DROP TABLE IF EXISTS w_classes;
|
|
|
CREATE TEMP TABLE w_classes AS
|
|
|
SELECT t_classes.oid
|
|
|
FROM compta.t_classes
|
|
|
JOIN compta.t_listes_tables ON table_id = t_listes_tables.oid
|
|
|
WHERE (SELECT valeur FROM compta.t_divers WHERE t_divers.code = 'X3SANA') IS DISTINCT FROM '1' AND
|
|
|
t_listes_tables.code = 'ANA' AND
|
|
|
sequence = 1;
|
|
|
|
|
|
|
|
|
INSERT INTO compta.t_classes_sections(
|
|
|
code, texte, classe_id)
|
|
|
SELECT CCE_0, MAX(DES_0) AS groupe_texte, w_classes.oid AS classe_id
|
|
|
FROM w_classes, prod_sagex3.CACCE
|
|
|
WHERE (SELECT valeur FROM compta.t_divers WHERE t_divers.code = 'X3SANA') IS DISTINCT FROM '1' AND
|
|
|
DIE_0 = 'AX1' AND
|
|
|
CCE_0 NOT IN (
|
|
|
SELECT t_classes_sections.code
|
|
|
FROM compta.t_classes_sections
|
|
|
JOIN w_classes ON classe_id = w_classes.oid
|
|
|
)
|
|
|
GROUP BY 1,3
|
|
|
ORDER BY 1;
|
|
|
|
|
|
UPDATE compta.t_classes_sections
|
|
|
SET texte = DES_0
|
|
|
FROM prod_sagex3.CACCE,
|
|
|
w_classes
|
|
|
WHERE (SELECT valeur FROM compta.t_divers WHERE t_divers.code = 'X3SANA') IS DISTINCT FROM '1' AND
|
|
|
DIE_0 = 'AX1' AND
|
|
|
classe_id = w_classes.oid AND
|
|
|
CCE_0 = t_classes_sections.code AND
|
|
|
t_classes_sections.texte IS DISTINCT FROM DES_0;
|
|
|
|
|
|
|
|
|
DELETE FROM compta.t_classes_sections
|
|
|
USING w_classes
|
|
|
WHERE (SELECT valeur FROM compta.t_divers WHERE t_divers.code = 'X3SANA') IS DISTINCT FROM '1' AND
|
|
|
classe_id = w_classes.oid AND
|
|
|
t_classes_sections.code NOT IN (
|
|
|
SELECT CCE_0 FROM prod_sagex3.CACCE WHERE DIE_0 = 'AX1'
|
|
|
);
|
|
|
|
|
|
DROP TABLE IF EXISTS w_classes_sections;
|
|
|
CREATE TEMP TABLE w_classes_sections AS
|
|
|
SELECT t_classes_sections.oid, code
|
|
|
FROM compta.t_classes_sections
|
|
|
JOIN w_classes ON classe_id = w_classes.oid
|
|
|
WHERE (SELECT valeur FROM compta.t_divers WHERE t_divers.code = 'X3SANA') IS DISTINCT FROM '1'
|
|
|
;
|
|
|
|
|
|
DELETE FROM compta.t_classes_sections_elements
|
|
|
WHERE (SELECT valeur FROM compta.t_divers WHERE t_divers.code = 'X3SANA') IS DISTINCT FROM '1' AND
|
|
|
section_id IN
|
|
|
(SELECT oid FROM w_classes_sections);
|
|
|
|
|
|
|
|
|
INSERT INTO compta.t_classes_sections_elements (section_id, to_id)
|
|
|
SELECT w_classes_sections.oid AS section_id, t_sections_analytiques.oid AS to_id
|
|
|
FROM w_classes_sections
|
|
|
JOIN compta.t_sections_analytiques ON
|
|
|
(t_sections_analytiques.code LIKE w_classes_sections.code || '_%' OR
|
|
|
t_sections_analytiques.code = w_classes_sections.code)
|
|
|
WHERE (SELECT valeur FROM compta.t_divers WHERE t_divers.code = 'X3SANA') IS DISTINCT FROM '1'
|
|
|
;
|
|
|
|
|
|
|
|
|
DELETE FROM compta.t_classes_sections
|
|
|
WHERE (SELECT valeur FROM compta.t_divers WHERE t_divers.code = 'X3SANA') IS DISTINCT FROM '1' AND
|
|
|
oid NOT IN (SELECT section_id FROM compta.t_classes_sections_elements);
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
INSERT INTO compta.t_classes(
|
|
|
code, texte, table_id, is_cti, sequence)
|
|
|
SELECT 'ANA2', 'Poste', t_listes_tables.oid, '1', 2
|
|
|
FROM compta.t_listes_tables
|
|
|
WHERE (SELECT valeur FROM compta.t_divers WHERE t_divers.code = 'X3SANA') IS DISTINCT FROM '1' AND
|
|
|
t_listes_tables.code = 'ANA' AND
|
|
|
(SELECT t_classes.oid
|
|
|
FROM compta.t_classes
|
|
|
JOIN compta.t_listes_tables ON table_id = t_listes_tables.oid
|
|
|
WHERE t_listes_tables.code = 'ANA' AND
|
|
|
sequence = 2) IS NULL;
|
|
|
|
|
|
DROP TABLE IF EXISTS w_classes;
|
|
|
CREATE TEMP TABLE w_classes AS
|
|
|
SELECT t_classes.oid
|
|
|
FROM compta.t_classes
|
|
|
JOIN compta.t_listes_tables ON table_id = t_listes_tables.oid
|
|
|
WHERE (SELECT valeur FROM compta.t_divers WHERE t_divers.code = 'X3SANA') IS DISTINCT FROM '1' AND
|
|
|
t_listes_tables.code = 'ANA' AND
|
|
|
sequence = 2;
|
|
|
|
|
|
|
|
|
INSERT INTO compta.t_classes_sections(
|
|
|
code, texte, classe_id)
|
|
|
SELECT CCE_0, MAX(DES_0) AS groupe_texte, w_classes.oid AS classe_id
|
|
|
FROM w_classes, prod_sagex3.CACCE
|
|
|
WHERE (SELECT valeur FROM compta.t_divers WHERE t_divers.code = 'X3SANA') IS DISTINCT FROM '1' AND
|
|
|
DIE_0 = 'AX2' AND
|
|
|
CCE_0 NOT IN (
|
|
|
SELECT t_classes_sections.code
|
|
|
FROM compta.t_classes_sections
|
|
|
JOIN w_classes ON classe_id = w_classes.oid
|
|
|
)
|
|
|
GROUP BY 1,3
|
|
|
ORDER BY 1;
|
|
|
|
|
|
UPDATE compta.t_classes_sections
|
|
|
SET texte = DES_0
|
|
|
FROM prod_sagex3.CACCE,
|
|
|
w_classes
|
|
|
WHERE (SELECT valeur FROM compta.t_divers WHERE t_divers.code = 'X3SANA') IS DISTINCT FROM '1' AND
|
|
|
DIE_0 = 'AX2' AND
|
|
|
classe_id = w_classes.oid AND
|
|
|
CCE_0 = t_classes_sections.code AND
|
|
|
t_classes_sections.texte IS DISTINCT FROM DES_0;
|
|
|
|
|
|
|
|
|
DELETE FROM compta.t_classes_sections
|
|
|
USING w_classes
|
|
|
WHERE (SELECT valeur FROM compta.t_divers WHERE t_divers.code = 'X3SANA') IS DISTINCT FROM '1' AND
|
|
|
classe_id = w_classes.oid AND
|
|
|
t_classes_sections.code NOT IN (
|
|
|
SELECT CCE_0 FROM prod_sagex3.CACCE WHERE DIE_0 = 'AX2'
|
|
|
);
|
|
|
|
|
|
DROP TABLE IF EXISTS w_classes_sections;
|
|
|
CREATE TEMP TABLE w_classes_sections AS
|
|
|
SELECT t_classes_sections.oid, code
|
|
|
FROM compta.t_classes_sections
|
|
|
JOIN w_classes ON classe_id = w_classes.oid
|
|
|
WHERE (SELECT valeur FROM compta.t_divers WHERE t_divers.code = 'X3SANA') IS DISTINCT FROM '1'
|
|
|
;
|
|
|
|
|
|
DELETE FROM compta.t_classes_sections_elements
|
|
|
WHERE (SELECT valeur FROM compta.t_divers WHERE t_divers.code = 'X3SANA') IS DISTINCT FROM '1' AND
|
|
|
section_id IN (SELECT oid FROM w_classes_sections);
|
|
|
|
|
|
|
|
|
INSERT INTO compta.t_classes_sections_elements (section_id, to_id)
|
|
|
SELECT w_classes_sections.oid AS section_id, t_sections_analytiques.oid AS to_id
|
|
|
FROM w_classes_sections
|
|
|
JOIN compta.t_sections_analytiques ON
|
|
|
(t_sections_analytiques.code LIKE '%_' || w_classes_sections.code OR
|
|
|
t_sections_analytiques.code = w_classes_sections.code)
|
|
|
WHERE (SELECT valeur FROM compta.t_divers WHERE t_divers.code = 'X3SANA') IS DISTINCT FROM '1'
|
|
|
;
|
|
|
|
|
|
|
|
|
DELETE FROM compta.t_classes_sections
|
|
|
WHERE (SELECT valeur FROM compta.t_divers WHERE t_divers.code = 'X3SANA') IS DISTINCT FROM '1' AND
|
|
|
oid NOT IN (SELECT section_id FROM compta.t_classes_sections_elements);
|
|
|
|
|
|
|
|
|
SELECT base.cti_update_classes('compta', 't_sections_analytiques', 'ANA','');
|
|
|
|
|
|
]]></sqlcmd>
|
|
|
|
|
|
</NODE>
|
|
|
|
|
|
|
|
|
|
|
|
</NODE>
|
|
|
|
|
|
<NODE name="CHIFFRIER" label="CREATION DU CHIFFRIER">
|
|
|
|
|
|
<condition><![CDATA[
|
|
|
"[MOISMODIFIES]" != "0"
|
|
|
]]></condition>
|
|
|
|
|
|
<NODE label="Récupération chiffrier">
|
|
|
<sqlcmd><![CDATA[
|
|
|
|
|
|
|
|
|
|
|
|
]]></sqlcmd>
|
|
|
</NODE>
|
|
|
|
|
|
|
|
|
</NODE>
|
|
|
|
|
|
<NODE name="PARAM" label="RECUPERATION DES PARAMETRES">
|
|
|
|
|
|
<condition><![CDATA[
|
|
|
"[MOISMODIFIES]" != "0"
|
|
|
]]></condition>
|
|
|
|
|
|
<NODE label="Paramètres">
|
|
|
<sqlcmd><![CDATA[
|
|
|
|
|
|
INSERT INTO compta.t_sites(code, texte, clinique_honoraire, code_original)
|
|
|
SELECT FACILITY.FCY_0, FACILITY.FCYNAM_0, 'C', FACILITY.FCY_0
|
|
|
FROM prod_sagex3.FACILITY
|
|
|
WHERE FACILITY.FCY_0 IN (SELECT FCY_0 FROM prod_sagex3.GACCENTRY) AND
|
|
|
FACILITY.FCY_0 NOT IN (SELECT code_original FROM compta.t_sites WHERE code_original IS NOT NULL)
|
|
|
ORDER BY FACILITY.FCY_0;
|
|
|
|
|
|
|
|
|
INSERT INTO compta.t_types_compta(code, code_original, texte, specialite)
|
|
|
SELECT code, code_original, texte, specialite
|
|
|
FROM
|
|
|
(
|
|
|
SELECT 'GES' AS code, 'GES' AS code_original, 'Gestion' AS texte, 'GES' AS specialite
|
|
|
UNION
|
|
|
SELECT 'BIL', 'BIL', 'Bilan', 'BIL'
|
|
|
) subview
|
|
|
WHERE code_original NOT IN (SELECT code_original FROM compta.t_types_compta WHERE code_original IS NOT NULL);
|
|
|
|
|
|
INSERT INTO compta.t_sections_analytiques(oid, code, code_original, texte)
|
|
|
SELECT 0, '0000', '', 'Non renseignée'
|
|
|
WHERE 0 NOT IN (SELECT oid FROM compta.t_sections_analytiques);
|
|
|
|
|
|
|
|
|
-- Traitement des sections analytiques
|
|
|
INSERT INTO compta.t_divers (code, texte, valeur, description)
|
|
|
SELECT
|
|
|
'X3SANA',
|
|
|
'Traitement des sections analytiques',
|
|
|
'1',
|
|
|
'0=Une section regroupée des 2 premières sections X3, 1=Utilisation des 6 sections dispo dans iCTI compta'
|
|
|
WHERE 'X3SANA' NOT IN (SELECT code FROM compta.t_divers);
|
|
|
;
|
|
|
|
|
|
-- Traitement ecritures d'ajustement
|
|
|
INSERT INTO compta.t_divers (code, texte, valeur, description)
|
|
|
SELECT
|
|
|
'X3AJUS',
|
|
|
'Traitement des ajustements',
|
|
|
'0',
|
|
|
'0=CAT_0=2 TYP_0=ODM LEDTYP_0<>1, 1=CAT_0=5'
|
|
|
WHERE 'X3AJUS' NOT IN (SELECT code FROM compta.t_divers);
|
|
|
;
|
|
|
|
|
|
|
|
|
INSERT INTO compta.t_partenaires(oid, code, code_original, texte, texte_court)
|
|
|
SELECT 0, chr(127) || '***', '', 'Non renseigné', 'Non renseigné'
|
|
|
WHERE 0 NOT IN (SELECT oid FROM compta.t_partenaires);
|
|
|
|
|
|
|
|
|
INSERT INTO compta.t_partenaires(code, code_original, texte, texte_court)
|
|
|
SELECT BPRNUM_0, BPRNUM_0, BPRNAM_0, CASE WHEN BPRSHO_0 <> '' THEN BPRSHO_0 ELSE BPRNAM_0 END
|
|
|
FROM prod_sagex3.BPARTNER
|
|
|
WHERE BPRNUM_0 NOT IN (SELECT code_original FROM compta.t_partenaires WHERE code_original IS NOT NULL)
|
|
|
ORDER BY BPRNUM_0;
|
|
|
|
|
|
|
|
|
|
|
|
INSERT INTO compta.t_journaux(code, code_original, texte, a_nouveaux, clinique_honoraire)
|
|
|
SELECT JOU_0, JOU_0, DES_0, CASE WHEN TYP_0 = 7 THEN '1' ELSE '0' END, 'C'
|
|
|
FROM prod_sagex3.GJOURNAL
|
|
|
WHERE JOU_0 NOT IN (SELECT code_original FROM compta.t_journaux WHERE code_original IS NOT NULL)
|
|
|
ORDER BY JOU_0;
|
|
|
|
|
|
|
|
|
INSERT INTO compta.t_comptes(
|
|
|
type_compta_id, numero, texte, compte_general_id, clinique_honoraire,
|
|
|
banque, collectif, type_compta_extra_id, numero_extra)
|
|
|
SELECT
|
|
|
COALESCE(t_types_compta.oid,0) AS type_compta_id,
|
|
|
GACCOUNT.ACC_0 AS numero,
|
|
|
MAX(GACCOUNT.DES_0) AS texte,
|
|
|
0 AS compte_general_id,
|
|
|
'C' AS clinique_honoraire,
|
|
|
MAX(CASE WHEN BANK.BAN_0 IS NOT NULL THEN '1' ELSE '0' END) AS banque,
|
|
|
'0' AS collectif,
|
|
|
0 AS type_compta_extra_id,
|
|
|
'' AS numero_extra
|
|
|
FROM prod_sagex3.GACCOUNT
|
|
|
LEFT JOIN prod_sagex3.BANK ON (GACCOUNT.ACC_0 = BANK.BANACC_0)
|
|
|
LEFT JOIN compta.t_types_compta ON CASE WHEN ACC_0 LIKE '6%' OR ACC_0 LIKE '7%' THEN 'GES' ELSE 'BIL' END = t_types_compta.code_original
|
|
|
WHERE SUBSTR(ACC_0,1,1) IN ('1','2','3','4','5','6','7','8','9') AND
|
|
|
ACC_0 NOT IN (SELECT numero FROM compta.t_comptes WHERE numero IS NOT NULL)
|
|
|
GROUP BY 1,2
|
|
|
ORDER BY 2;
|
|
|
|
|
|
UPDATE compta.t_comptes SET compte_general_id = oid
|
|
|
WHERE type_compta_id IN (SELECT oid FROM compta.t_types_compta
|
|
|
WHERE code IN ('BIL', 'GES')) AND compte_general_id <> oid AND partenaire_id = 0;
|
|
|
|
|
|
-- Type auxiliaire par défaut selon première lettre du 'raccourci X3' si présent dans types de compta
|
|
|
UPDATE compta.t_comptes
|
|
|
SET type_compta_extra_id = t_types_compta.oid
|
|
|
FROM compta.t_comptes t_comptes_nonsigne
|
|
|
JOIN prod_sagex3.GACCOUNT ON t_comptes_nonsigne.numero = ACC_0
|
|
|
JOIN compta.t_types_compta ON substr(ACCSHO_0,1,1) = t_types_compta.code_original
|
|
|
WHERE t_comptes.compte_nonsigne_id = t_comptes_nonsigne.oid AND
|
|
|
ACCSHO_0 <> '' AND
|
|
|
t_comptes.type_compta_extra_id <> t_types_compta.oid
|
|
|
;
|
|
|
|
|
|
|
|
|
INSERT INTO compta.t_classes_comptes(code, texte)
|
|
|
SELECT CLSCOD_0, CLSNAM_0
|
|
|
FROM prod_sagex3.GACCCLS
|
|
|
WHERE CLSCOD_0 NOT IN (SELECT code FROM compta.t_classes_comptes WHERE code IS NOT NULL)
|
|
|
ORDER BY CLSCOD_0;
|
|
|
|
|
|
UPDATE compta.t_classes_comptes
|
|
|
SET texte = CLSNAM_0
|
|
|
FROM prod_sagex3.GACCCLS
|
|
|
WHERE code = CLSCOD_0 AND texte = '';
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
]]></sqlcmd>
|
|
|
</NODE>
|
|
|
|
|
|
</NODE>
|
|
|
|
|
|
</ROOT>
|