|
|
<?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_historique_ecritures_total;
|
|
|
CREATE TEMP TABLE w_historique_ecritures_total AS
|
|
|
SELECT mois_comptable, t_comptes.numero as numero, SUM(montant_debit) as debit, SUM(montant_credit) as credit, SUM(nombre_ecritures) as count
|
|
|
FROM compta.p_historique_ecritures_total
|
|
|
JOIN compta.t_comptes ON p_historique_ecritures_total.compte_extra_id = t_comptes.oid
|
|
|
WHERE mois_comptable >= 200801 AND
|
|
|
is_budget IS DISTINCT FROM '1'
|
|
|
GROUP BY 1,2
|
|
|
ORDER BY 1,2;
|
|
|
|
|
|
-- Ecritures exercice en cours
|
|
|
DROP TABLE IF EXISTS w_ECRITURES;
|
|
|
CREATE TEMP TABLE w_ECRITURES AS
|
|
|
SELECT to_number(to_char(CASE WHEN PERIODEECRITURE < DEBUTEXERCICE THEN DEBUTEXERCICE ELSE PERIODEECRITURE END,'YYYYMM'),'FM999999') AS MOIS,
|
|
|
NUMEROCOMPTE,
|
|
|
date_part('year',FINEXERCICE) AS exercice_comptable,
|
|
|
'0'::text AS exercice_precedent,
|
|
|
date(MIN(PERIODEECRITURE)) AS PERIODEECRITURE_debut,
|
|
|
date(MAX(PERIODEECRITURE)) AS PERIODEECRITURE_fin,
|
|
|
Count(*) AS COUNT,
|
|
|
round(SUM(MONTANTTENUDEBIT),2) AS DEBIT,
|
|
|
round(SUM(MONTANTTENUCREDIT),2) AS CREDIT
|
|
|
FROM prod_quadracompta.ECRITURES
|
|
|
JOIN prod_quadracompta.DOSSIER1 ON 1=1
|
|
|
WHERE TYPELIGNE <> 'T'
|
|
|
GROUP BY 1,2,3
|
|
|
ORDER BY 1,2;
|
|
|
-- Ecritures exercice précédent
|
|
|
INSERT INTO w_ECRITURES
|
|
|
SELECT to_number(to_char(CASE WHEN PERIODEECRITURE < DEBUTEXERCICE THEN DEBUTEXERCICE ELSE PERIODEECRITURE END,'YYYYMM'),'FM999999') AS MOIS,
|
|
|
NUMEROCOMPTE,
|
|
|
date_part('year',FINEXERCICE) AS exercice_comptable,
|
|
|
'1'::text AS exercice_precedent,
|
|
|
date(MIN(PERIODEECRITURE)) AS PERIODEECRITURE_debut,
|
|
|
date(MAX(PERIODEECRITURE)) AS PERIODEECRITURE_fin,
|
|
|
Count(*) AS COUNT,
|
|
|
round(SUM(MONTANTTENUDEBIT),2) AS DEBIT,
|
|
|
round(SUM(MONTANTTENUCREDIT),2) AS CREDIT
|
|
|
FROM prod_quadracompta.ECRITURESP
|
|
|
JOIN prod_quadracompta.DOSSIER1P ON 1=1
|
|
|
WHERE TYPELIGNE <> 'T'
|
|
|
GROUP BY 1,2,3
|
|
|
ORDER BY 1,2;
|
|
|
|
|
|
|
|
|
DROP TABLE IF EXISTS w_mois_modifies;
|
|
|
CREATE TEMP TABLE w_mois_modifies AS
|
|
|
SELECT w_ECRITURES.exercice_comptable,
|
|
|
w_ECRITURES.exercice_precedent,
|
|
|
w_ECRITURES.mois AS mois_comptable,
|
|
|
MIN(PERIODEECRITURE_debut) AS PERIODEECRITURE_debut,
|
|
|
MAX(PERIODEECRITURE_fin) AS PERIODEECRITURE_fin
|
|
|
FROM w_ECRITURES
|
|
|
LEFT JOIN w_historique_ecritures_total ON
|
|
|
w_historique_ecritures_total.mois_comptable = w_ECRITURES.mois AND
|
|
|
w_historique_ecritures_total.numero = w_ECRITURES.NUMEROCOMPTE
|
|
|
GROUP BY 1,2,3
|
|
|
HAVING MAX(CASE WHEN w_historique_ecritures_total.count IS DISTINCT FROM w_ECRITURES.count OR
|
|
|
w_historique_ecritures_total.debit IS DISTINCT FROM w_ECRITURES.debit OR
|
|
|
w_historique_ecritures_total.credit IS DISTINCT FROM w_ECRITURES.credit
|
|
|
THEN 1 ELSE 0 END) = 1;
|
|
|
|
|
|
ALTER TABLE w_mois_modifies ADD CONSTRAINT w_mois_modifies_pk PRIMARY KEY(mois_comptable);
|
|
|
|
|
|
CTISELECT_PROPERTY_READ 'MOISMODIFIES', COALESCE(base.cti_group_concat(mois_comptable),'0')
|
|
|
FROM w_mois_modifies;
|
|
|
|
|
|
CTISELECT_PROPERTY_READ 'MOISMODIFIESC', COALESCE(base.cti_group_concat(mois_comptable),'0')
|
|
|
FROM w_mois_modifies
|
|
|
WHERE exercice_precedent = '0';
|
|
|
|
|
|
CTISELECT_PROPERTY_READ 'MOISMODIFIESP', COALESCE(base.cti_group_concat(mois_comptable),'0')
|
|
|
FROM w_mois_modifies
|
|
|
WHERE exercice_precedent = '1';
|
|
|
|
|
|
echo Mois modifiés Exercice en cours : [MOISMODIFIESC];
|
|
|
echo Mois modifiés Exercice précédent : [MOISMODIFIESP];
|
|
|
|
|
|
]]></sqlcmd>
|
|
|
</NODE>
|
|
|
|
|
|
|
|
|
|
|
|
</NODE>
|
|
|
|
|
|
<NODE name="ECRITURES" label="RECUPERATION ECRITURES">
|
|
|
<condition><![CDATA[
|
|
|
"[MOISMODIFIESC]" != "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 p_historique_ecritures.mois_comptable = w_mois_modifies.mois_comptable AND
|
|
|
w_mois_modifies.exercice_precedent = '0' 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');
|
|
|
|
|
|
|
|
|
SELECT base.cti_disable_index('compta', 'i_historique_ecritures_total_1');
|
|
|
|
|
|
|
|
|
|
|
|
]]></sqlcmd>
|
|
|
</NODE>
|
|
|
|
|
|
<NODE label="Génération détail">
|
|
|
<sqlcmd><![CDATA[
|
|
|
|
|
|
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,
|
|
|
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
|
|
|
t_sites.oid AS site_id,
|
|
|
t_comptes.type_compta_id,
|
|
|
t_comptes.compte_general_id AS compte_id,
|
|
|
date(PERIODEECRITURE + (JOURECRITURE || ' day')::interval - interval '1 day') AS date_ecriture,
|
|
|
w_mois_modifies.exercice_comptable,
|
|
|
w_mois_modifies.mois_comptable,
|
|
|
t_comptes.clinique_honoraire,
|
|
|
t_journaux.oid AS journal_id,
|
|
|
0::bigint AS section_analytique_id,
|
|
|
t_comptes.partenaire_id,
|
|
|
t_comptes.oid AS compte_extra_id,
|
|
|
'1'::text AS comptabilisee,
|
|
|
'0'::text AS fin_exercice,
|
|
|
'0'::text AS ajustement,
|
|
|
'0'::text AS inter_site,
|
|
|
folio || '.' || lignefolio || '/' || numuniq AS cle_originale,
|
|
|
numuniq AS identifiant_operation,
|
|
|
COALESCE(t_comptes_contre.oid,0) AS compte_contrepartie_id,
|
|
|
substr(LIBELLE,1,100) AS texte,
|
|
|
'20991231'::date AS date_facture_fournisseur,
|
|
|
substr(NUMEROPIECE,1,255) AS piece,
|
|
|
substr(NUMEROPIECE,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,
|
|
|
MONTANTTENUCREDIT AS montant_credit,
|
|
|
MONTANTTENUDEBIT AS montant_debit
|
|
|
FROM prod_quadracompta.ECRITURES
|
|
|
JOIN w_mois_modifies ON
|
|
|
date(PERIODEECRITURE) BETWEEN PERIODEECRITURE_debut AND PERIODEECRITURE_fin AND
|
|
|
w_mois_modifies.exercice_precedent = '0'
|
|
|
JOIN compta.t_sites ON t_sites.oid = 1
|
|
|
JOIN compta.t_journaux ON CODEJOURNAL = t_journaux.code_original
|
|
|
JOIN compta.t_comptes ON NUMEROCOMPTE = t_comptes.numero
|
|
|
LEFT JOIN compta.t_comptes t_comptes_contre ON COMPTECONTREPARTIE = t_comptes_contre.numero
|
|
|
WHERE TYPELIGNE <> 'T'
|
|
|
ORDER BY FOLIO, LIGNEFOLIO;
|
|
|
|
|
|
|
|
|
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="ECRITURES" label="RECUPERATION ECRITURES (exercice précédent)">
|
|
|
<condition><![CDATA[
|
|
|
"[MOISMODIFIESP]" != "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 p_historique_ecritures.mois_comptable = w_mois_modifies.mois_comptable AND
|
|
|
w_mois_modifies.exercice_precedent = '1' 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');
|
|
|
|
|
|
|
|
|
SELECT base.cti_disable_index('compta', 'i_historique_ecritures_total_1');
|
|
|
|
|
|
|
|
|
|
|
|
]]></sqlcmd>
|
|
|
</NODE>
|
|
|
|
|
|
<NODE label="Génération détail">
|
|
|
<sqlcmd><![CDATA[
|
|
|
|
|
|
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,
|
|
|
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
|
|
|
t_sites.oid AS site_id,
|
|
|
t_comptes.type_compta_id,
|
|
|
t_comptes.compte_general_id AS compte_id,
|
|
|
date(PERIODEECRITURE + (JOURECRITURE || ' day')::interval - interval '1 day') AS date_ecriture,
|
|
|
w_mois_modifies.exercice_comptable,
|
|
|
w_mois_modifies.mois_comptable,
|
|
|
t_comptes.clinique_honoraire,
|
|
|
t_journaux.oid AS journal_id,
|
|
|
0::bigint AS section_analytique_id,
|
|
|
t_comptes.partenaire_id,
|
|
|
t_comptes.oid AS compte_extra_id,
|
|
|
'1'::text AS comptabilisee,
|
|
|
'0'::text AS fin_exercice,
|
|
|
'0'::text AS ajustement,
|
|
|
'0'::text AS inter_site,
|
|
|
folio || '.' || lignefolio || '/' || numuniq AS cle_originale,
|
|
|
numuniq AS identifiant_operation,
|
|
|
COALESCE(t_comptes_contre.oid,0) AS compte_contrepartie_id,
|
|
|
substr(LIBELLE,1,100) AS texte,
|
|
|
'20991231'::date AS date_facture_fournisseur,
|
|
|
substr(NUMEROPIECE,1,255) AS piece,
|
|
|
substr(NUMEROPIECE,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,
|
|
|
MONTANTTENUCREDIT AS montant_credit,
|
|
|
MONTANTTENUDEBIT AS montant_debit
|
|
|
FROM prod_quadracompta.ECRITURESP
|
|
|
JOIN w_mois_modifies ON
|
|
|
date(PERIODEECRITURE) BETWEEN PERIODEECRITURE_debut AND PERIODEECRITURE_fin AND
|
|
|
w_mois_modifies.exercice_precedent = '1'
|
|
|
JOIN compta.t_sites ON t_sites.oid = 1
|
|
|
JOIN compta.t_journaux ON CODEJOURNAL = t_journaux.code_original
|
|
|
JOIN compta.t_comptes ON NUMEROCOMPTE = t_comptes.numero
|
|
|
LEFT JOIN compta.t_comptes t_comptes_contre ON COMPTECONTREPARTIE = t_comptes_contre.numero
|
|
|
WHERE TYPELIGNE <> 'T'
|
|
|
ORDER BY FOLIO, LIGNEFOLIO;
|
|
|
|
|
|
|
|
|
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="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>
|
|
|
|
|
|
<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">
|
|
|
|
|
|
<NODE label="Paramètres">
|
|
|
<sqlcmd><![CDATA[
|
|
|
|
|
|
-- Periode comptable
|
|
|
UPDATE base.p_calendrier_mois SET
|
|
|
exercice_mois_comptable_1 = subview.exercice_mois_comptable_1,
|
|
|
exercice_comptable = subview.exercice_comptable
|
|
|
FROM
|
|
|
(
|
|
|
SELECT p_calendrier_mois.mois,
|
|
|
p_calendrier_mois.mois - correcteur_mois AS exercice_mois_comptable_1,
|
|
|
date_part('year',p_calendrier_mois.date_debut) - correcteur_exercice AS exercice_comptable
|
|
|
FROM
|
|
|
base.p_calendrier_mois
|
|
|
JOIN (
|
|
|
SELECT
|
|
|
p_calendrier_mois.mois,
|
|
|
to_number(to_char(DEBUTEXERCICE,'YYYYMM'),'FM999999') AS exercice_mois_comptable_1,
|
|
|
date_part('year',FINEXERCICE) AS exercice_comptable,
|
|
|
p_calendrier_mois.numero_mois,
|
|
|
p_calendrier_mois.mois - to_number(to_char(DEBUTEXERCICE,'YYYYMM'),'FM999999') AS correcteur_mois,
|
|
|
date_part('year',p_calendrier_mois.date_debut) - date_part('year',FINEXERCICE) AS correcteur_exercice
|
|
|
FROM base.p_calendrier_mois
|
|
|
JOIN prod_quadracompta.DOSSIER1 ON p_calendrier_mois.date_debut BETWEEN date(DEBUTEXERCICE) AND date(FINEXERCICE)
|
|
|
ORDER BY 1
|
|
|
) subview ON p_calendrier_mois.numero_mois = subview.numero_mois
|
|
|
WHERE p_calendrier_mois.exercice_mois_comptable_1 IS DISTINCT FROM p_calendrier_mois.mois - correcteur_mois OR
|
|
|
p_calendrier_mois.exercice_comptable IS DISTINCT FROM date_part('year',p_calendrier_mois.date_debut) - correcteur_exercice
|
|
|
order by 1) subview
|
|
|
WHERE p_calendrier_mois.mois = subview.mois;
|
|
|
|
|
|
-- Site = FINESS
|
|
|
INSERT INTO compta.t_sites(oid, code, texte, clinique_honoraire, code_original)
|
|
|
SELECT 1::bigint, t_finess.code, t_finess.texte, 'C', t_finess.code
|
|
|
FROM base.t_finess
|
|
|
WHERE 1 NOT IN (SELECT oid FROM compta.t_sites WHERE oid = 1)
|
|
|
ORDER BY t_finess.oid
|
|
|
LIMIT 1;
|
|
|
|
|
|
|
|
|
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'
|
|
|
UNION
|
|
|
SELECT 'CLI', 'CLI', 'Clients', 'CLI'
|
|
|
UNION
|
|
|
SELECT 'FOU', 'FOU', 'Fournisseurs', 'FOU'
|
|
|
) 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_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_journaux(code, code_original, texte, a_nouveaux, clinique_honoraire)
|
|
|
SELECT JOURNAUX.CODE, JOURNAUX.CODE, JOURNAUX.LIBELLE, '0', 'C'
|
|
|
FROM prod_quadracompta.JOURNAUX
|
|
|
WHERE JOURNAUX.CODE NOT IN (SELECT code_original FROM compta.t_journaux WHERE code_original IS NOT NULL)
|
|
|
ORDER BY 1;
|
|
|
|
|
|
|
|
|
INSERT INTO compta.t_journaux(code, code_original, texte, a_nouveaux, clinique_honoraire)
|
|
|
SELECT JOURNAUX.CODE, JOURNAUX.CODE, JOURNAUX.LIBELLE, '0', 'C'
|
|
|
FROM prod_quadracompta.JOURNAUXP JOURNAUX
|
|
|
WHERE JOURNAUX.CODE NOT IN (SELECT code_original FROM compta.t_journaux WHERE code_original IS NOT NULL)
|
|
|
ORDER BY 1;
|
|
|
|
|
|
INSERT INTO compta.t_journaux(code, code_original, texte, a_nouveaux, clinique_honoraire)
|
|
|
SELECT CODEJOURNAL, CODEJOURNAL, CODEJOURNAL, '0', 'C'
|
|
|
FROM prod_quadracompta.ECRITURES
|
|
|
WHERE CODEJOURNAL NOT IN (SELECT code_original FROM compta.t_journaux WHERE code_original IS NOT NULL)
|
|
|
GROUP BY 1
|
|
|
ORDER BY 1;
|
|
|
|
|
|
INSERT INTO compta.t_journaux(code, code_original, texte, a_nouveaux, clinique_honoraire)
|
|
|
SELECT CODEJOURNAL, CODEJOURNAL, CODEJOURNAL, '0', 'C'
|
|
|
FROM prod_quadracompta.ECRITURESP ECRITURES
|
|
|
WHERE CODEJOURNAL NOT IN (SELECT code_original FROM compta.t_journaux WHERE code_original IS NOT NULL)
|
|
|
GROUP BY 1
|
|
|
ORDER BY 1;
|
|
|
|
|
|
UPDATE compta.t_comptes SET
|
|
|
type_compta_id = subview.type_compta_id,
|
|
|
texte = subview.texte
|
|
|
FROM
|
|
|
(
|
|
|
SELECT
|
|
|
COALESCE(t_types_compta.oid,0) AS type_compta_id,
|
|
|
NUMERO AS numero,
|
|
|
MAX(INTITULE) AS texte
|
|
|
FROM prod_quadracompta.COMPTES
|
|
|
LEFT JOIN compta.t_types_compta ON
|
|
|
CASE
|
|
|
WHEN TYPE = 'C' THEN 'CLI'
|
|
|
WHEN TYPE = 'F' THEN 'FOU'
|
|
|
WHEN TYPE = 'G' AND NUMERO LIKE '6%' OR NUMERO LIKE '7%' OR NUMERO LIKE '8%' THEN 'GES'
|
|
|
ELSE 'BIL' END
|
|
|
= t_types_compta.code_original
|
|
|
GROUP BY 1,2
|
|
|
) subview
|
|
|
WHERE t_comptes.numero = subview.numero AND
|
|
|
(
|
|
|
t_comptes.type_compta_id IS DISTINCT FROM subview.type_compta_id OR
|
|
|
t_comptes.texte IS DISTINCT FROM subview.texte
|
|
|
);
|
|
|
|
|
|
UPDATE compta.t_comptes SET
|
|
|
type_compta_id = subview.type_compta_id,
|
|
|
texte = subview.texte
|
|
|
FROM
|
|
|
(
|
|
|
SELECT
|
|
|
COALESCE(t_types_compta.oid,0) AS type_compta_id,
|
|
|
NUMERO AS numero,
|
|
|
MAX(INTITULE) AS texte
|
|
|
FROM prod_quadracompta.COMPTESP COMPTES
|
|
|
LEFT JOIN compta.t_types_compta ON
|
|
|
CASE
|
|
|
WHEN TYPE = 'C' THEN 'CLI'
|
|
|
WHEN TYPE = 'F' THEN 'FOU'
|
|
|
WHEN TYPE = 'G' AND NUMERO LIKE '6%' OR NUMERO LIKE '7%' OR NUMERO LIKE '8%' THEN 'GES'
|
|
|
ELSE 'BIL' END
|
|
|
= t_types_compta.code_original
|
|
|
GROUP BY 1,2
|
|
|
) subview
|
|
|
WHERE t_comptes.numero = subview.numero AND
|
|
|
(
|
|
|
t_comptes.type_compta_id IS DISTINCT FROM subview.type_compta_id OR
|
|
|
t_comptes.texte IS DISTINCT FROM subview.texte
|
|
|
);
|
|
|
|
|
|
INSERT INTO compta.t_comptes(
|
|
|
type_compta_id, numero, texte, compte_general_id, clinique_honoraire,
|
|
|
banque, collectif, type_compta_extra_id, numero_extra, partenaire_id)
|
|
|
SELECT
|
|
|
COALESCE(t_types_compta.oid,0) AS type_compta_id,
|
|
|
NUMERO AS numero,
|
|
|
MAX(INTITULE) AS texte,
|
|
|
0 AS compte_general_id,
|
|
|
'C' AS clinique_honoraire,
|
|
|
MAX(CASE WHEN NUMERO LIKE '512%' THEN '1' ELSE '0' END) AS banque,
|
|
|
'0' AS collectif,
|
|
|
0 AS type_compta_extra_id,
|
|
|
'' AS numero_extra,
|
|
|
0::bigint AS partenaire_id
|
|
|
FROM prod_quadracompta.COMPTES
|
|
|
LEFT JOIN compta.t_types_compta ON
|
|
|
CASE
|
|
|
WHEN TYPE = 'C' THEN 'CLI'
|
|
|
WHEN TYPE = 'F' THEN 'FOU'
|
|
|
WHEN TYPE = 'G' AND NUMERO LIKE '6%' OR NUMERO LIKE '7%' OR NUMERO LIKE '8%' THEN 'GES'
|
|
|
ELSE 'BIL' END
|
|
|
= t_types_compta.code_original
|
|
|
WHERE NUMERO NOT IN (SELECT numero FROM compta.t_comptes WHERE numero IS NOT NULL)
|
|
|
GROUP BY 1,2
|
|
|
ORDER BY 2;
|
|
|
|
|
|
INSERT INTO compta.t_comptes(
|
|
|
type_compta_id, numero, texte, compte_general_id, clinique_honoraire,
|
|
|
banque, collectif, type_compta_extra_id, numero_extra, partenaire_id)
|
|
|
SELECT
|
|
|
COALESCE(t_types_compta.oid,0) AS type_compta_id,
|
|
|
NUMERO AS numero,
|
|
|
MAX(INTITULE) AS texte,
|
|
|
0 AS compte_general_id,
|
|
|
'C' AS clinique_honoraire,
|
|
|
MAX(CASE WHEN NUMERO LIKE '512%' THEN '1' ELSE '0' END) AS banque,
|
|
|
'0' AS collectif,
|
|
|
0 AS type_compta_extra_id,
|
|
|
'' AS numero_extra,
|
|
|
0::bigint AS partenaire_id
|
|
|
FROM prod_quadracompta.COMPTESP COMPTES
|
|
|
LEFT JOIN compta.t_types_compta ON
|
|
|
CASE
|
|
|
WHEN TYPE = 'C' THEN 'CLI'
|
|
|
WHEN TYPE = 'F' THEN 'FOU'
|
|
|
WHEN TYPE = 'G' AND NUMERO LIKE '6%' OR NUMERO LIKE '7%' OR NUMERO LIKE '8%' THEN 'GES'
|
|
|
ELSE 'BIL' END
|
|
|
= t_types_compta.code_original
|
|
|
WHERE NUMERO 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 = subview.compte_general_id,
|
|
|
collectif = subview.collectif
|
|
|
FROM (
|
|
|
SELECT t_comptes.oid,
|
|
|
COALESCE(t_comptes_c.oid,t_comptes.oid) AS compte_general_id,
|
|
|
CASE WHEN COMPTES.TYPE <> 'G' THEN '0' ELSE '1' END AS collectif
|
|
|
FROM prod_quadracompta.COMPTESP COMPTES
|
|
|
JOIN compta.t_comptes ON t_comptes.numero = COMPTES.NUMERO
|
|
|
LEFT JOIN prod_quadracompta.COMPTESP COMPTES_C ON COMPTES.COLLECTIF = COMPTES_C.NUMERO AND COMPTES.TYPE <> 'G'
|
|
|
LEFT JOIN compta.t_comptes t_comptes_c ON t_comptes_c.numero = COMPTES_C.NUMERO
|
|
|
) subview
|
|
|
WHERE t_comptes.oid = subview.oid AND
|
|
|
(
|
|
|
t_comptes.compte_general_id IS DISTINCT FROM subview.compte_general_id OR
|
|
|
t_comptes.collectif IS DISTINCT FROM subview.collectif
|
|
|
);
|
|
|
|
|
|
|
|
|
UPDATE compta.t_comptes SET
|
|
|
compte_general_id = subview.compte_general_id,
|
|
|
collectif = subview.collectif
|
|
|
FROM (
|
|
|
SELECT t_comptes.oid,
|
|
|
COALESCE(t_comptes_c.oid,t_comptes.oid) AS compte_general_id,
|
|
|
CASE WHEN COMPTES.TYPE <> 'G' THEN '0' ELSE '1' END AS collectif
|
|
|
FROM prod_quadracompta.COMPTES
|
|
|
JOIN compta.t_comptes ON t_comptes.numero = COMPTES.NUMERO
|
|
|
LEFT JOIN prod_quadracompta.COMPTES COMPTES_C ON COMPTES.COLLECTIF = COMPTES_C.NUMERO AND COMPTES.TYPE <> 'G'
|
|
|
LEFT JOIN compta.t_comptes t_comptes_c ON t_comptes_c.numero = COMPTES_C.NUMERO
|
|
|
) subview
|
|
|
WHERE t_comptes.oid = subview.oid AND
|
|
|
(
|
|
|
t_comptes.compte_general_id IS DISTINCT FROM subview.compte_general_id OR
|
|
|
t_comptes.collectif IS DISTINCT FROM subview.collectif
|
|
|
);
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
]]></sqlcmd>
|
|
|
</NODE>
|
|
|
|
|
|
</NODE>
|
|
|
|
|
|
</ROOT>
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|