<?xml version="1.0" encoding="ISO-8859-1"?>
|
|
<ROOT>
|
|
|
|
|
|
<NODE name="INIT" label="INITIALISATIONS">
|
|
|
|
<NODE label="Détection Mois modifiés">
|
|
<sqlcmd><![CDATA[
|
|
|
|
-- Préparation table globale
|
|
DROP TABLE IF EXISTS w_GACCENTRY_DA;
|
|
CREATE TEMP TABLE w_GACCENTRY_DA AS
|
|
SELECT
|
|
GACCENTRYD.TYP_0,
|
|
GACCENTRYD.NUM_0,
|
|
GACCENTRYD.LIG_0,
|
|
CASE WHEN GACCENTRYD.ACC_0 <> '' THEN GACCENTRYD.ACC_0 ELSE COALESCE(GACCENTRYA.CNA_0,GACCENTRYD.CNA_0) END AS ACC_0,
|
|
COALESCE(GACCENTRYA.ANALIG_0,0) AS ANALIG_0,
|
|
GACCENTRYD.ACCDAT_0,
|
|
GACCENTRYD.DES_0,
|
|
GACCENTRYD.FCYLIN_0,
|
|
GACCENTRYD.BPR_0,
|
|
GACCENTRYD.OFFACC_0,
|
|
GACCENTRYD.SNS_0,
|
|
CASE
|
|
WHEN round(GACCENTRYD.AMTCUR_0::numeric ,2) = round(GACCENTRYD.AMTLOC_0::numeric ,2)
|
|
THEN COALESCE(GACCENTRYA.AMTCUR_0,GACCENTRYD.AMTCUR_0)
|
|
ELSE COALESCE(GACCENTRYA.AMTLOC_0,GACCENTRYD.AMTLOC_0)
|
|
END AS AMTCUR_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
|
|
FROM prod_adonix.GACCENTRYD
|
|
JOIN w_FACILITY FACILITY ON GACCENTRYD.FCYLIN_0 = FACILITY.FCY_0
|
|
LEFT JOIN prod_adonix.GACCENTRYA ON
|
|
GACCENTRYD.TYP_0 = GACCENTRYA.TYP_0 AND
|
|
GACCENTRYD.NUM_0 = GACCENTRYA.NUM_0 AND
|
|
GACCENTRYD.LIG_0 = GACCENTRYA.LIG_0;
|
|
|
|
-- Suppression écritures avec compte inexistant (UO)
|
|
DELETE FROM w_GACCENTRY_DA
|
|
WHERE acc_0 NOT IN (SELECT acc_0 FROM prod_adonix.GACCOUNT)
|
|
;
|
|
|
|
|
|
CREATE INDEX w_GACCENTRY_DA_i1
|
|
ON w_GACCENTRY_DA
|
|
USING btree
|
|
(TYP_0, NUM_0);
|
|
|
|
|
|
DROP TABLE IF EXISTS w_GACCENTRY_EDA;
|
|
CREATE TEMP TABLE w_GACCENTRY_EDA AS
|
|
SELECT
|
|
to_char(PERIOD.PEREND_0, 'YYYYMM')::numeric AS MOIS,
|
|
PERIOD.PEREND_0,
|
|
GACCENTRY.TYP_0,
|
|
GACCENTRY.CAT_0,
|
|
GACCENTRY.NUM_0,
|
|
GACCENTRY.JOU_0,
|
|
GACCENTRY.REF_0,
|
|
GACCENTRY.BPRVCR_0,
|
|
GACCENTRY.BPRDATVCR_0,
|
|
w_GACCENTRY_DA.LIG_0,
|
|
w_GACCENTRY_DA.ACC_0,
|
|
w_GACCENTRY_DA.ANALIG_0,
|
|
w_GACCENTRY_DA.ACCDAT_0,
|
|
w_GACCENTRY_DA.DES_0,
|
|
w_GACCENTRY_DA.FCYLIN_0,
|
|
w_GACCENTRY_DA.BPR_0,
|
|
w_GACCENTRY_DA.OFFACC_0,
|
|
w_GACCENTRY_DA.SNS_0,
|
|
w_GACCENTRY_DA.AMTCUR_0,
|
|
round(CASE WHEN SNS_0 > 0 THEN AMTCUR_0 ELSE 0 END::numeric,2) AS AMTCUR_debit,
|
|
round(CASE WHEN SNS_0 < 0 THEN AMTCUR_0 ELSE 0 END::numeric,2) AS AMTCUR_credit,
|
|
w_GACCENTRY_DA.CCE_0,
|
|
w_GACCENTRY_DA.CCE_1,
|
|
w_GACCENTRY_DA.CCE_2,
|
|
w_GACCENTRY_DA.CCE_3,
|
|
w_GACCENTRY_DA.CCE_4,
|
|
w_GACCENTRY_DA.CCE_5,
|
|
FCYLIN_0 || '|' ||
|
|
JOU_0 || '|' ||
|
|
BPR_0 || '|' ||
|
|
ACC_0 || '|' ||
|
|
CCE_0 || '|' ||
|
|
CCE_1 || '|' ||
|
|
CCE_2 || '|' ||
|
|
CCE_3 || '|' ||
|
|
CCE_4 || '|' ||
|
|
CCE_5 || '|' ||
|
|
OFFACC_0 AS key
|
|
FROM prod_adonix.GACCENTRY
|
|
JOIN prod_adonix.GTYPACCENT ON GACCENTRY.TYP_0 = GTYPACCENT.TYP_0
|
|
JOIN prod_adonix.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
|
|
JOIN w_GACCENTRY_DA ON w_GACCENTRY_DA.NUM_0 = GACCENTRY.NUM_0 AND
|
|
w_GACCENTRY_DA.TYP_0 = GACCENTRY.TYP_0
|
|
WHERE GACCENTRY.CAT_0 <> 5
|
|
;
|
|
|
|
|
|
DROP TABLE IF EXISTS w_GACCENTRYD;
|
|
CREATE TEMP TABLE w_GACCENTRYD AS
|
|
SELECT MOIS,
|
|
ACC_0,
|
|
Count(*) AS COUNT,
|
|
round(SUM(AMTCUR_debit)::numeric,2) AS DEBIT,
|
|
round(SUM(AMTCUR_credit)::numeric,2) AS CREDIT
|
|
FROM w_GACCENTRY_EDA
|
|
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(montant_debit) as debit, SUM(montant_credit) as credit, SUM(nombre_ecritures) as count
|
|
FROM compta.p_historique_ecritures_total, compta.t_comptes
|
|
WHERE mois_comptable >= 200801 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
|
|
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];
|
|
|
|
]]></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_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,
|
|
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 partenaire_id,
|
|
0::bigint AS compte_extra_id,
|
|
0::bigint AS compte_contrepartie_id
|
|
FROM w_GACCENTRY_EDA
|
|
JOIN w_mois_modifies ON mois_modifie = w_GACCENTRY_EDA.MOIS
|
|
GROUP BY 1,2,3,4,5,6,7,8,9,10,11,12,13;
|
|
|
|
|
|
|
|
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;
|
|
|
|
UPDATE w_GACCENTRY_keys
|
|
SET section_analytique_id = t_sections_analytiques.oid
|
|
FROM compta.t_sections_analytiques
|
|
WHERE 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 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 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 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 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 CCE_5 <> '' AND code_original = CCE_5;
|
|
|
|
|
|
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_EDA_i1
|
|
ON w_GACCENTRY_EDA
|
|
USING btree
|
|
(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,
|
|
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,
|
|
partenaire_id,
|
|
compte_extra_id,
|
|
'1'::text AS comptabilisee,
|
|
'0'::text AS fin_exercice,
|
|
CASE WHEN CAT_0 = '5' THEN '3' ELSE '0'::text END AS ajustement,
|
|
'0'::text AS inter_site,
|
|
TYP_0 || '-' || NUM_0 || '-' || to_char(LIG_0,'FM00000') || CASE WHEN COALESCE(ANALIG_0,0) > 1 THEN '-' || to_char(ANALIG_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 > '20000101' 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_EDA
|
|
JOIN w_mois_modifies ON mois_modifie = w_GACCENTRY_EDA.MOIS
|
|
JOIN w_GACCENTRY_keys ON w_GACCENTRY_keys.key = w_GACCENTRY_EDA.key
|
|
ORDER BY NUM_0, TYP_0, LIG_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[
|
|
|
|
-- Determination des comptes collectifs selon ecritures
|
|
DROP TABLE IF EXISTS w_comptes_collectifs;
|
|
CREATE TEMP TABLE w_comptes_collectifs AS
|
|
select compte_id
|
|
from compta.p_historique_ecritures
|
|
WHERE partenaire_id <> 0
|
|
group by 1
|
|
HAVING count(DISTINCT partenaire_id) > 1
|
|
ORDER BY 1;
|
|
|
|
UPDATE compta.t_comptes
|
|
SET collectif = '1',
|
|
type_compta_extra_id = type_compta_id,
|
|
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 type_compta_extra_id AS type_compta_id,
|
|
replace(t_comptes.numero_extra, '*', t_partenaires.code) AS numero,
|
|
replace(t_comptes.texte_extra, '*', t_partenaires.texte_court) AS texte,
|
|
t_comptes.compte_nonsigne_id AS compte_general_id,
|
|
t_comptes.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 AND t_comptes.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);
|
|
|
|
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 w_comptes_extra ON p_historique_ecritures.compte_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
|
|
LIMIT 5.,
|
|
|
|
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'
|
|
,
|
|
100
|
|
);
|
|
|
|
|
|
|
|
]]></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[
|
|
|
|
|
|
|
|
]]></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[
|
|
|
|
-- Site choisi
|
|
DROP TABLE IF EXISTS w_FACILITY;
|
|
CREATE TEMP TABLE w_FACILITY AS
|
|
SELECT FCY_0, FCYNAM_0
|
|
FROM prod_adonix.FACILITY
|
|
WHERE FCY_0::text = ANY (string_to_array('[ETAB]'::text,',')) OR
|
|
'[ETAB]' = ''
|
|
;
|
|
|
|
CREATE INDEX w_FACILITY_FCY_0
|
|
ON w_FACILITY
|
|
USING btree
|
|
(FCY_0);
|
|
|
|
INSERT INTO compta.t_sites(code, texte, clinique_honoraire, code_original)
|
|
SELECT FACILITY.FCY_0, FACILITY.FCYNAM_0, 'C', FACILITY.FCY_0
|
|
FROM w_FACILITY FACILITY
|
|
WHERE 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);
|
|
|
|
INSERT INTO compta.t_sections_analytiques(code, code_original, texte)
|
|
SELECT CCE_0, CCE_0, MAX(DES_0)
|
|
FROM prod_adonix.CACCE
|
|
WHERE CCE_0 <> '' AND
|
|
CCE_0 IN (SELECT CCE_0 FROM prod_adonix.GACCENTRYA) AND
|
|
CCE_0 NOT IN (SELECT code_original FROM compta.t_sections_analytiques WHERE code_original IS NOT NULL)
|
|
GROUP BY 1
|
|
;
|
|
|
|
|
|
INSERT INTO compta.t_sections_analytiques(code, code_original, texte)
|
|
SELECT CCE_0, CCE_0, MAX(DES_0)
|
|
FROM prod_adonix.CACCE
|
|
WHERE CCE_0 <> '' AND
|
|
CCE_0 IN (SELECT CCE_1 FROM prod_adonix.GACCENTRYA) AND
|
|
CCE_0 NOT IN (SELECT code_original FROM compta.t_sections_analytiques WHERE code_original IS NOT NULL)
|
|
GROUP BY 1
|
|
;
|
|
|
|
|
|
--INSERT INTO compta.t_sections_analytiques(code, code_original, texte)
|
|
--SELECT CCE_0, CCE_0, MAX(DES_0)
|
|
--FROM prod_adonix.CACCE
|
|
--WHERE CCE_0 <> '' AND
|
|
-- CCE_0 IN (SELECT CCE_2 FROM prod_adonix.GACCENTRYA) AND
|
|
-- CCE_0 NOT IN (SELECT code_original FROM compta.t_sections_analytiques WHERE code_original IS NOT NULL)
|
|
--GROUP BY 1
|
|
--;
|
|
|
|
INSERT INTO compta.t_sections_analytiques(code, code_original, texte)
|
|
SELECT CCE_0, CCE_0, MAX(DES_0)
|
|
FROM prod_adonix.CACCE
|
|
WHERE CCE_0 <> '' AND
|
|
CCE_0 IN (SELECT CCE_3 FROM prod_adonix.GACCENTRYA) AND
|
|
CCE_0 NOT IN (SELECT code_original FROM compta.t_sections_analytiques WHERE code_original IS NOT NULL)
|
|
GROUP BY 1
|
|
;
|
|
|
|
INSERT INTO compta.t_sections_analytiques(code, code_original, texte)
|
|
SELECT CCE_0, CCE_0, MAX(DES_0)
|
|
FROM prod_adonix.CACCE
|
|
WHERE CCE_0 <> '' AND
|
|
CCE_0 IN (SELECT CCE_4 FROM prod_adonix.GACCENTRYA) AND
|
|
CCE_0 NOT IN (SELECT code_original FROM compta.t_sections_analytiques WHERE code_original IS NOT NULL)
|
|
GROUP BY 1
|
|
;
|
|
|
|
INSERT INTO compta.t_sections_analytiques(code, code_original, texte)
|
|
SELECT CCE_0, CCE_0, MAX(DES_0)
|
|
FROM prod_adonix.CACCE
|
|
WHERE CCE_0 <> '' AND
|
|
CCE_0 IN (SELECT CCE_5 FROM prod_adonix.GACCENTRYA) AND
|
|
CCE_0 NOT IN (SELECT code_original FROM compta.t_sections_analytiques WHERE code_original IS NOT NULL)
|
|
GROUP BY 1
|
|
;
|
|
|
|
|
|
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_adonix.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_adonix.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_adonix.GACCOUNT
|
|
LEFT JOIN prod_adonix.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 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;
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
]]></sqlcmd>
|
|
</NODE>
|
|
|
|
</NODE>
|
|
|
|
</ROOT>
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|