<?xml version="1.0" encoding="ISO-8859-1"?>
|
|
<ROOT>
|
|
|
|
|
|
<NODE name="INIT" label="INITIALISATIONS">
|
|
|
|
|
|
<NODE label="Détection Mois modifiés">
|
|
<sqlcmd><![CDATA[
|
|
|
|
]]></sqlcmd>
|
|
</NODE>
|
|
|
|
</NODE>
|
|
|
|
<NODE name="ECRITURES" label="RECUPERATION ECRITURES">
|
|
<condition><![CDATA[
|
|
]]></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');
|
|
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');
|
|
|
|
TRUNCATE compta.p_historique_ecritures ;
|
|
TRUNCATE compta.p_historique_ecritures_total ;
|
|
|
|
]]></sqlcmd>
|
|
</NODE>
|
|
|
|
<NODE label="Génération détail">
|
|
<sqlcmd><![CDATA[
|
|
|
|
-- Ecritures comptables
|
|
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
|
|
COALESCE(t_sites.oid,0) AS site_id,
|
|
t_comptes.type_compta_id,
|
|
t_comptes.oid AS compte_id,
|
|
date(w_ZZGEC.DTEC::text) AS date_ecriture,
|
|
substr(w_ZZGEC.DTCT,1,4)::numeric AS exercice_comptable,
|
|
substr(w_ZZGEC.DTCT,1,6)::numeric AS mois_comptable,
|
|
'C'::text AS clinique_honoraire,
|
|
t_journaux.oid AS journal_id,
|
|
COALESCE(t_sections_analytiques_0.oid,0) AS section_analytique_id,
|
|
COALESCE(t_sections_analytiques_1.oid,0) AS section_analytique_2_id,
|
|
COALESCE(t_sections_analytiques_2.oid,0) AS section_analytique_3_id,
|
|
COALESCE(t_sections_analytiques_3.oid,0) AS section_analytique_4_id,
|
|
COALESCE(t_sections_analytiques_4.oid,0) AS section_analytique_5_id,
|
|
COALESCE(t_sections_analytiques_5.oid,0) AS section_analytique_6_id,
|
|
COALESCE(t_partenaires.oid,0) AS partenaire_id,
|
|
t_comptes_extra.oid AS compte_extra_id,
|
|
'1'::text AS comptabilisee,
|
|
'0'::text AS fin_exercice,
|
|
'0' AS ajustement,
|
|
'0'::text AS inter_site,
|
|
w_ZZGEC.CORI || '-' || w_ZZGEC.NPIE || '-' || w_ZZGEC.DNOR AS cle_originale,
|
|
w_ZZGEC.CORI || '-' || w_ZZGEC.NPIE || '-' || w_ZZGEC.DNOR AS identifiant_operation,
|
|
COALESCE(t_comptes_contrepartie.oid,0) AS compte_contrepartie_id,
|
|
substr(w_ZZGEC.LECR,1,100) AS texte,
|
|
'20991231' AS date_facture_fournisseur,
|
|
'' AS piece,
|
|
'' AS dossier,
|
|
'20991231'::date AS date_echeance,
|
|
0::bigint AS journal_paiement_id,
|
|
0::bigint AS mode_paiement_id,
|
|
''::text AS numero_cheque,
|
|
COALESCE(MOA1_C,MON1_C),
|
|
COALESCE(MOA1_D,MON1_D)
|
|
FROM w_ZZGEC
|
|
LEFT JOIN w_ZZGEA ON w_ZZGEA.oid_GEC = w_ZZGEC.oid
|
|
LEFT JOIN compta.t_sites ON w_ZZGEC.ETAB_CTI = t_sites.code_original
|
|
JOIN compta.t_comptes ON w_ZZGEC.CPTC = t_comptes.numero
|
|
JOIN compta.t_comptes t_comptes_extra ON w_ZZGEC.NCPT_CTI = t_comptes_extra.numero
|
|
LEFT JOIN compta.t_comptes t_comptes_contrepartie ON w_ZZGEC.CCTC = t_comptes_contrepartie.numero
|
|
JOIN compta.t_journaux ON w_ZZGEC.JRNRCORI = t_journaux.code_original
|
|
LEFT JOIN compta.t_sections_analytiques t_sections_analytiques_0 ON AXE0 = t_sections_analytiques_0.code_original AND t_sections_analytiques_0.oid <> 0
|
|
LEFT JOIN compta.t_sections_analytiques t_sections_analytiques_1 ON AXE1 = t_sections_analytiques_1.code_original AND t_sections_analytiques_1.oid <> 0
|
|
LEFT JOIN compta.t_sections_analytiques t_sections_analytiques_2 ON AXE2 = t_sections_analytiques_2.code_original AND t_sections_analytiques_2.oid <> 0
|
|
LEFT JOIN compta.t_sections_analytiques t_sections_analytiques_3 ON AXE3 = t_sections_analytiques_3.code_original AND t_sections_analytiques_3.oid <> 0
|
|
LEFT JOIN compta.t_sections_analytiques t_sections_analytiques_4 ON AXE4 = t_sections_analytiques_4.code_original AND t_sections_analytiques_4.oid <> 0
|
|
LEFT JOIN compta.t_sections_analytiques t_sections_analytiques_5 ON AXE5 = t_sections_analytiques_5.code_original AND t_sections_analytiques_5.oid <> 0
|
|
LEFT JOIN compta.t_partenaires ON w_ZZGEC.NCPTPART = t_partenaires.code_original AND t_partenaires.oid <> 0
|
|
;
|
|
|
|
-- Ecritures ajustement analytique
|
|
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
|
|
COALESCE(t_sites.oid,0) AS site_id,
|
|
t_comptes.type_compta_id,
|
|
t_comptes.oid AS compte_id,
|
|
date(w_ZZGEA.DTEC::text) AS date_ecriture,
|
|
substr(w_ZZGEA.DTCT,1,4)::numeric AS exercice_comptable,
|
|
substr(w_ZZGEA.DTCT,1,6)::numeric AS mois_comptable,
|
|
'C'::text AS clinique_honoraire,
|
|
t_journaux.oid AS journal_id,
|
|
COALESCE(t_sections_analytiques_0.oid,0) AS section_analytique_id,
|
|
COALESCE(t_sections_analytiques_1.oid,0) AS section_analytique_2_id,
|
|
COALESCE(t_sections_analytiques_2.oid,0) AS section_analytique_3_id,
|
|
COALESCE(t_sections_analytiques_3.oid,0) AS section_analytique_4_id,
|
|
COALESCE(t_sections_analytiques_4.oid,0) AS section_analytique_5_id,
|
|
COALESCE(t_sections_analytiques_5.oid,0) AS section_analytique_6_id,
|
|
COALESCE(t_partenaires.oid,0) AS partenaire_id,
|
|
t_comptes_extra.oid AS compte_extra_id,
|
|
'0'::text AS comptabilisee,
|
|
'0'::text AS fin_exercice,
|
|
'2' AS ajustement,
|
|
'0'::text AS inter_site,
|
|
w_ZZGEA.CORI || '-' || w_ZZGEA.NPIE || '-' || w_ZZGEA.DNOR AS cle_originale,
|
|
w_ZZGEA.CORI || '-' || w_ZZGEA.NPIE || '-' || w_ZZGEA.DNOR AS identifiant_operation,
|
|
COALESCE(t_comptes_contrepartie.oid,0) AS compte_contrepartie_id,
|
|
substr(LECR,1,100) AS texte,
|
|
'20991231' AS date_facture_fournisseur,
|
|
'' AS piece,
|
|
'' AS dossier,
|
|
'20991231'::date AS date_echeance,
|
|
0::bigint AS journal_paiement_id,
|
|
0::bigint AS mode_paiement_id,
|
|
''::text AS numero_cheque,
|
|
COALESCE(MOA1_C),
|
|
COALESCE(MOA1_D)
|
|
FROM w_ZZGEA
|
|
LEFT JOIN compta.t_sites ON ETAB_CTI = t_sites.code_original
|
|
JOIN compta.t_comptes ON w_ZZGEA.CPTC = t_comptes.numero
|
|
JOIN compta.t_comptes t_comptes_extra ON NCPT_CTI = t_comptes_extra.numero
|
|
LEFT JOIN compta.t_comptes t_comptes_contrepartie ON CCTC = t_comptes_contrepartie.numero
|
|
JOIN compta.t_journaux ON JRNRCORI = t_journaux.code_original
|
|
LEFT JOIN compta.t_sections_analytiques t_sections_analytiques_0 ON AXE0 = t_sections_analytiques_0.code_original AND t_sections_analytiques_0.oid <> 0
|
|
LEFT JOIN compta.t_sections_analytiques t_sections_analytiques_1 ON AXE1 = t_sections_analytiques_1.code_original AND t_sections_analytiques_1.oid <> 0
|
|
LEFT JOIN compta.t_sections_analytiques t_sections_analytiques_2 ON AXE2 = t_sections_analytiques_2.code_original AND t_sections_analytiques_2.oid <> 0
|
|
LEFT JOIN compta.t_sections_analytiques t_sections_analytiques_3 ON AXE3 = t_sections_analytiques_3.code_original AND t_sections_analytiques_3.oid <> 0
|
|
LEFT JOIN compta.t_sections_analytiques t_sections_analytiques_4 ON AXE4 = t_sections_analytiques_4.code_original AND t_sections_analytiques_4.oid <> 0
|
|
LEFT JOIN compta.t_sections_analytiques t_sections_analytiques_5 ON AXE5 = t_sections_analytiques_5.code_original AND t_sections_analytiques_5.oid <> 0
|
|
LEFT JOIN compta.t_partenaires ON NCPTPART = t_partenaires.code_original AND t_partenaires.oid <> 0
|
|
WHERE oid_GEC = 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[
|
|
]]></condition>
|
|
|
|
|
|
|
|
|
|
|
|
</NODE>
|
|
|
|
<NODE name="CHIFFRIER" label="CREATION DU CHIFFRIER">
|
|
|
|
<condition><![CDATA[
|
|
]]></condition>
|
|
|
|
<NODE label="Récupération chiffrier">
|
|
<sqlcmd><![CDATA[
|
|
|
|
TRUNCATE compta.p_chiffrier_comptable;
|
|
|
|
INSERT INTO compta.p_chiffrier_comptable
|
|
(
|
|
mois_comptable,
|
|
site_id,
|
|
clinique_honoraire,
|
|
montant_debit,
|
|
montant_credit
|
|
)
|
|
SELECT
|
|
(EXER||to_char(mois,'FM00'))::numeric AS mois_comptable,
|
|
COALESCE(t_sites.oid,0) AS site_id,
|
|
'C'::text AS clinique_honoraire,
|
|
SUM(
|
|
CASE mois
|
|
WHEN 01 THEN D1AN+D101
|
|
WHEN 02 THEN D102
|
|
WHEN 03 THEN D103
|
|
WHEN 04 THEN D104
|
|
WHEN 05 THEN D105
|
|
WHEN 06 THEN D106
|
|
WHEN 07 THEN D107
|
|
WHEN 08 THEN D108
|
|
WHEN 09 THEN D109
|
|
WHEN 10 THEN D110
|
|
WHEN 11 THEN D111
|
|
WHEN 12 THEN D112
|
|
END
|
|
),
|
|
SUM(
|
|
CASE mois
|
|
WHEN 01 THEN C1AN+C101
|
|
WHEN 02 THEN C102
|
|
WHEN 03 THEN C103
|
|
WHEN 04 THEN C104
|
|
WHEN 05 THEN C105
|
|
WHEN 06 THEN C106
|
|
WHEN 07 THEN C107
|
|
WHEN 08 THEN C108
|
|
WHEN 09 THEN C109
|
|
WHEN 10 THEN C110
|
|
WHEN 11 THEN C111
|
|
WHEN 12 THEN C112
|
|
END
|
|
)
|
|
FROM prod_talentia_finance.IFTW2FGHM_ZZGLD
|
|
JOIN
|
|
(
|
|
SELECT generate_series AS mois FROM generate_series(1,12)
|
|
) subview ON 1=1
|
|
LEFT JOIN compta.t_sites ON (CSTE||ETAB) = t_sites.code_original
|
|
WHERE EXER >= '2014' AND NCPT BETWEEN '1' AND '9'
|
|
GROUP BY 1,2,3
|
|
;
|
|
|
|
INSERT INTO compta.p_chiffrier_comptable
|
|
(
|
|
mois_comptable,
|
|
site_id,
|
|
clinique_honoraire,
|
|
montant_debit,
|
|
montant_credit
|
|
)
|
|
SELECT
|
|
(EXER||to_char(mois,'FM00'))::numeric AS mois_comptable,
|
|
COALESCE(t_sites.oid,0) AS site_id,
|
|
'C'::text AS clinique_honoraire,
|
|
SUM(
|
|
CASE mois
|
|
WHEN 01 THEN D1AN+D101
|
|
WHEN 02 THEN D102
|
|
WHEN 03 THEN D103
|
|
WHEN 04 THEN D104
|
|
WHEN 05 THEN D105
|
|
WHEN 06 THEN D106
|
|
WHEN 07 THEN D107
|
|
WHEN 08 THEN D108
|
|
WHEN 09 THEN D109
|
|
WHEN 10 THEN D110
|
|
WHEN 11 THEN D111
|
|
WHEN 12 THEN D112
|
|
END
|
|
),
|
|
SUM(
|
|
CASE mois
|
|
WHEN 01 THEN C1AN+C101
|
|
WHEN 02 THEN C102
|
|
WHEN 03 THEN C103
|
|
WHEN 04 THEN C104
|
|
WHEN 05 THEN C105
|
|
WHEN 06 THEN C106
|
|
WHEN 07 THEN C107
|
|
WHEN 08 THEN C108
|
|
WHEN 09 THEN C109
|
|
WHEN 10 THEN C110
|
|
WHEN 11 THEN C111
|
|
WHEN 12 THEN C112
|
|
END
|
|
)
|
|
FROM prod_talentia_finance.IFTW2FGHM_ZHGLD
|
|
JOIN
|
|
(
|
|
SELECT generate_series AS mois FROM generate_series(1,12)
|
|
) subview ON 1=1
|
|
LEFT JOIN compta.t_sites ON (CSTE||ETAB) = t_sites.code_original
|
|
WHERE EXER >= '2014' AND NCPT BETWEEN '1' AND '9'
|
|
GROUP BY 1,2,3
|
|
;
|
|
|
|
|
|
|
|
TRUNCATE compta.p_chiffrier_comptable_compte;
|
|
|
|
INSERT INTO compta.p_chiffrier_comptable_compte
|
|
(
|
|
mois_comptable,
|
|
compte_id,
|
|
site_id,
|
|
clinique_honoraire,
|
|
montant_debit,
|
|
montant_credit
|
|
)
|
|
SELECT
|
|
(EXER||to_char(mois,'FM00'))::numeric AS mois_comptable,
|
|
COALESCE(t_comptes.oid,0) AS compte_id,
|
|
COALESCE(t_sites.oid,0) AS site_id,
|
|
'C'::text AS clinique_honoraire,
|
|
SUM(
|
|
CASE mois
|
|
WHEN 01 THEN D1AN+D101
|
|
WHEN 02 THEN D102
|
|
WHEN 03 THEN D103
|
|
WHEN 04 THEN D104
|
|
WHEN 05 THEN D105
|
|
WHEN 06 THEN D106
|
|
WHEN 07 THEN D107
|
|
WHEN 08 THEN D108
|
|
WHEN 09 THEN D109
|
|
WHEN 10 THEN D110
|
|
WHEN 11 THEN D111
|
|
WHEN 12 THEN D112
|
|
END
|
|
),
|
|
SUM(
|
|
CASE mois
|
|
WHEN 01 THEN C1AN+C101
|
|
WHEN 02 THEN C102
|
|
WHEN 03 THEN C103
|
|
WHEN 04 THEN C104
|
|
WHEN 05 THEN C105
|
|
WHEN 06 THEN C106
|
|
WHEN 07 THEN C107
|
|
WHEN 08 THEN C108
|
|
WHEN 09 THEN C109
|
|
WHEN 10 THEN C110
|
|
WHEN 11 THEN C111
|
|
WHEN 12 THEN C112
|
|
END
|
|
)
|
|
FROM prod_talentia_finance.IFTW2FGHM_ZZGLD
|
|
JOIN
|
|
(
|
|
SELECT generate_series AS mois FROM generate_series(1,12)
|
|
) subview ON 1=1
|
|
LEFT JOIN compta.t_sites ON (CSTE||ETAB) = t_sites.code_original
|
|
LEFT JOIN compta.t_comptes ON NCPT = t_comptes.numero
|
|
WHERE EXER >= '2014' AND NCPT BETWEEN '1' AND '9'
|
|
GROUP BY 1,2,3
|
|
;
|
|
|
|
INSERT INTO compta.p_chiffrier_comptable_compte
|
|
(
|
|
mois_comptable,
|
|
compte_id,
|
|
site_id,
|
|
clinique_honoraire,
|
|
montant_debit,
|
|
montant_credit
|
|
)
|
|
SELECT
|
|
(EXER||to_char(mois,'FM00'))::numeric AS mois_comptable,
|
|
COALESCE(t_comptes.oid,0) AS compte_id,
|
|
COALESCE(t_sites.oid,0) AS site_id,
|
|
'C'::text AS clinique_honoraire,
|
|
SUM(
|
|
CASE mois
|
|
WHEN 01 THEN D1AN+D101
|
|
WHEN 02 THEN D102
|
|
WHEN 03 THEN D103
|
|
WHEN 04 THEN D104
|
|
WHEN 05 THEN D105
|
|
WHEN 06 THEN D106
|
|
WHEN 07 THEN D107
|
|
WHEN 08 THEN D108
|
|
WHEN 09 THEN D109
|
|
WHEN 10 THEN D110
|
|
WHEN 11 THEN D111
|
|
WHEN 12 THEN D112
|
|
END
|
|
),
|
|
SUM(
|
|
CASE mois
|
|
WHEN 01 THEN C1AN+C101
|
|
WHEN 02 THEN C102
|
|
WHEN 03 THEN C103
|
|
WHEN 04 THEN C104
|
|
WHEN 05 THEN C105
|
|
WHEN 06 THEN C106
|
|
WHEN 07 THEN C107
|
|
WHEN 08 THEN C108
|
|
WHEN 09 THEN C109
|
|
WHEN 10 THEN C110
|
|
WHEN 11 THEN C111
|
|
WHEN 12 THEN C112
|
|
END
|
|
)
|
|
FROM prod_talentia_finance.IFTW2FGHM_ZHGLD
|
|
JOIN
|
|
(
|
|
SELECT generate_series AS mois FROM generate_series(1,12)
|
|
) subview ON 1=1
|
|
LEFT JOIN compta.t_sites ON (CSTE||ETAB) = t_sites.code_original
|
|
LEFT JOIN compta.t_comptes ON NCPT = t_comptes.numero
|
|
WHERE EXER >= '2014' AND NCPT BETWEEN '1' AND '9'
|
|
GROUP BY 1,2,3
|
|
;
|
|
|
|
]]></sqlcmd>
|
|
</NODE>
|
|
|
|
|
|
</NODE>
|
|
|
|
<NODE name="PARAM" label="RECUPERATION DES PARAMETRES">
|
|
|
|
|
|
<NODE label="Préparation tables">
|
|
<sqlcmd><![CDATA[
|
|
DROP TABLE IF EXISTS w_ZZGEC;
|
|
DROP SEQUENCE IF EXISTS s_ZZGEC;
|
|
|
|
CREATE TEMP SEQUENCE s_ZZGEC;
|
|
|
|
CREATE TEMP TABLE w_ZZGEC AS
|
|
SELECT
|
|
nextval('s_ZZGEC'::regclass) AS oid,
|
|
'ZZGEC'::text AS source,
|
|
ZZGEC.CSTE,
|
|
ZZGEC.ETAB,
|
|
ZZGEC.CORI,
|
|
ZZPOR.JRNR,
|
|
ZZGEC.CORI AS JRNRCORI,
|
|
DNOR,
|
|
NPIE,
|
|
LECR,
|
|
SENS,
|
|
DTCT AS DTEC,
|
|
DTCT,
|
|
ZZGEC.CSTE||ZZGEC.ETAB AS ETAB_CTI,
|
|
CASE WHEN NCPT = CPTC THEN CPTC ELSE CPTC || '-' || NCPT END AS NCPT_CTI,
|
|
NCPT,
|
|
CASE WHEN NCPT = CPTC THEN '' ELSE NCPT END AS NCPTPART,
|
|
CPTC,
|
|
CONT AS CONT_CTI,
|
|
CONT,
|
|
CONT AS CCTC,
|
|
CASE WHEN SENS = 'C' THEN MON1 ELSE 0 END AS MON1_C,
|
|
CASE WHEN SENS = 'D' THEN MON1 ELSE 0 END AS MON1_D
|
|
FROM prod_talentia_finance.IFTW2FGHM_ZZGEC ZZGEC
|
|
JOIN prod_talentia_finance.IFTW2FGHM_ZZPOR ZZPOR ON
|
|
ZZGEC.CORI = ZZPOR.CORI
|
|
WHERE ZZGEC.CORI <> 'RESULT' AND ZZPOR.JRNR <> ''
|
|
;
|
|
|
|
UPDATE w_ZZGEC
|
|
SET DTCT = subview.DTCT,
|
|
JRNR = 'AN'
|
|
FROM
|
|
(
|
|
SELECT MIN(DTCT) AS DTCT
|
|
FROM w_ZZGEC
|
|
WHERE source = 'ZZGEC' AND
|
|
JRNR <> 'AN' AND
|
|
CPTC LIKE '6%'
|
|
) subview
|
|
WHERE w_ZZGEC.source = 'ZZGEC' AND
|
|
w_ZZGEC.DTEC < subview.DTCT
|
|
;
|
|
|
|
|
|
|
|
INSERT INTO w_ZZGEC
|
|
SELECT
|
|
nextval('s_ZZGEC'::regclass) AS oid,
|
|
'ZHGEC'::text AS source,
|
|
ZZGEC.CSTE,
|
|
ZZGEC.ETAB,
|
|
ZZGEC.CORI,
|
|
ZZPOR.JRNR,
|
|
ZZGEC.CORI AS JRNRCORI,
|
|
DNOR,
|
|
NPIE,
|
|
LECR,
|
|
SENS,
|
|
DTCT AS DTEC,
|
|
DTCT,
|
|
ZZGEC.CSTE||ZZGEC.ETAB AS ETAB_CTI,
|
|
CASE WHEN NCPT = CPTC THEN CPTC ELSE CPTC || '-' || NCPT END AS NCPT_CTI,
|
|
NCPT,
|
|
CASE WHEN NCPT = CPTC THEN '' ELSE NCPT END AS NCPTPART,
|
|
CPTC,
|
|
CONT AS CONT_CTI,
|
|
CONT,
|
|
CONT AS CCTC,
|
|
CASE WHEN SENS = 'C' THEN MON1 ELSE 0 END AS MON1_C,
|
|
CASE WHEN SENS = 'D' THEN MON1 ELSE 0 END AS MON1_D
|
|
FROM prod_talentia_finance.IFTW2FGHM_ZHGEC ZZGEC
|
|
JOIN prod_talentia_finance.IFTW2FGHM_ZZPOR ZZPOR ON
|
|
ZZGEC.CORI = ZZPOR.CORI
|
|
WHERE JRNR <> '' AND ZZGEC.CORI <> 'RESULT' AND ZZGEC.CORI <> 'ANOUV' AND
|
|
DTCT >= 20140101 AND ZZPOR.JRNR <> ''
|
|
;
|
|
|
|
INSERT INTO w_ZZGEC
|
|
SELECT
|
|
nextval('s_ZZGEC'::regclass) AS oid,
|
|
'ZHGLG'::text AS source,
|
|
ZZGEC.CSTE,
|
|
ZZGEC.ETAB,
|
|
'ANOUV' AS CORI,
|
|
'AN' AS JRNR,
|
|
'AN' AS JRNRCORI,
|
|
0 AS DNOR,
|
|
'' AS NPIE,
|
|
'A NOUVEAUX' AS LECR,
|
|
'D' AS SENS,
|
|
(EXER||'0101')::numeric AS DTEC,
|
|
(EXER||'0101')::numeric AS DTCT,
|
|
ZZGEC.CSTE||ZZGEC.ETAB AS ETAB_CTI,
|
|
CASE WHEN NCPT = CPTC THEN CPTC ELSE CPTC || '-' || NCPT END AS NCPT_CTI,
|
|
NCPT,
|
|
'' AS NCPTPART,
|
|
CPTC,
|
|
'' AS CONT_CTI,
|
|
'',
|
|
'' AS CCTC,
|
|
0 AS MON1_C,
|
|
D1AN AS MON1_D
|
|
FROM prod_talentia_finance.IFTW2FGHM_ZHGLD ZZGEC
|
|
WHERE D1AN <> 0 AND
|
|
NCPT = CPTC AND
|
|
EXER >= '2014'
|
|
;
|
|
|
|
INSERT INTO w_ZZGEC
|
|
SELECT
|
|
nextval('s_ZZGEC'::regclass) AS oid,
|
|
'ZHGLG'::text AS source,
|
|
ZZGEC.CSTE,
|
|
ZZGEC.ETAB,
|
|
'ANOUV' AS CORI,
|
|
'AN' AS JRNR,
|
|
'AN' AS JRNRCORI,
|
|
0 AS DNOR,
|
|
'' AS NPIE,
|
|
'A NOUVEAUX' AS LECR,
|
|
'C' AS SENS,
|
|
(EXER||'0101')::numeric AS DTEC,
|
|
(EXER||'0101')::numeric AS DTCT,
|
|
ZZGEC.CSTE||ZZGEC.ETAB AS ETAB_CTI,
|
|
CASE WHEN NCPT = CPTC THEN CPTC ELSE CPTC || '-' || NCPT END AS NCPT_CTI,
|
|
NCPT,
|
|
'' AS NCPTPART,
|
|
CPTC,
|
|
'' AS CONT_CTI,
|
|
'',
|
|
'' AS CCTC,
|
|
C1AN AS MON1_C,
|
|
0 AS MON1_D
|
|
FROM prod_talentia_finance.IFTW2FGHM_ZHGLD ZZGEC
|
|
WHERE C1AN <> 0 AND
|
|
NCPT = CPTC AND
|
|
EXER >= '2014'
|
|
;
|
|
|
|
UPDATE w_ZZGEC
|
|
SET CCTC = subview.CPTC
|
|
FROM
|
|
(
|
|
SELECT NCPT, (MAX(Array[to_char(nb,'FM000000000000'), CPTC]))[2] AS CPTC
|
|
FROM
|
|
(
|
|
SELECT NCPT, CPTC, count(*) AS nb
|
|
FROM w_ZZGEC
|
|
GROUP BY 1,2
|
|
) subview
|
|
GROUP BY 1
|
|
) subview
|
|
WHERE w_ZZGEC.CONT <> '' AND
|
|
w_ZZGEC.CONT = subview.NCPT
|
|
;
|
|
|
|
UPDATE w_ZZGEC
|
|
SET JRNRCORI = 'AN'
|
|
WHERE JRNR = 'AN'
|
|
;
|
|
|
|
ANALYSE w_ZZGEC;
|
|
|
|
|
|
|
|
|
|
|
|
DROP TABLE IF EXISTS w_ZZGEA;
|
|
CREATE TEMP TABLE w_ZZGEA AS
|
|
SELECT
|
|
'ZZGEC'::text AS source,
|
|
0::bigint AS oid_GEC,
|
|
ZZGEA.CSTE,
|
|
ZZGEA.ETAB,
|
|
ZZGEA.CORI,
|
|
ZZPOR.JRNR,
|
|
ZZGEA.CORI AS JRNRCORI,
|
|
DNOR,
|
|
NPIE,
|
|
LECR,
|
|
SENS,
|
|
DTCT AS DTEC,
|
|
DTCT,
|
|
ZZGEA.CSTE||ZZGEA.ETAB AS ETAB_CTI,
|
|
CASE WHEN NCPT = CPTC THEN CPTC ELSE CPTC || '-' || NCPT END AS NCPT_CTI,
|
|
NCPT,
|
|
CASE WHEN NCPT = CPTC THEN '' ELSE NCPT END AS NCPTPART,
|
|
CPTC,
|
|
''::text AS CONT_CTI,
|
|
''::text AS CONT,
|
|
''::text AS CCTC,
|
|
CASE WHEN AXE0 <> '' THEN AXE0||'-0' ELSE '' END AS AXE0,
|
|
CASE WHEN AXE1 <> '' THEN AXE1||'-1' ELSE '' END AS AXE1,
|
|
CASE WHEN AXE2 <> '' THEN AXE2||'-2' ELSE '' END AS AXE2,
|
|
CASE WHEN AXE3 <> '' THEN AXE3||'-3' ELSE '' END AS AXE3,
|
|
CASE WHEN AXE4 <> '' THEN AXE4||'-4' ELSE '' END AS AXE4,
|
|
CASE WHEN AXE5 <> '' THEN AXE5||'-5' ELSE '' END AS AXE5,
|
|
CASE WHEN AXE6 <> '' THEN AXE6||'-6' ELSE '' END AS AXE6,
|
|
CASE WHEN AXE7 <> '' THEN AXE7||'-7' ELSE '' END AS AXE7,
|
|
CASE WHEN AXE8 <> '' THEN AXE8||'-8' ELSE '' END AS AXE8,
|
|
CASE WHEN AXE9 <> '' THEN AXE9||'-9' ELSE '' END AS AXE9,
|
|
CASE WHEN SENS = 'C' THEN MOA1 ELSE 0 END AS MOA1_C,
|
|
CASE WHEN SENS = 'D' THEN MOA1 ELSE 0 END AS MOA1_D
|
|
FROM prod_talentia_finance.IFTW2FGHM_ZZGEA ZZGEA
|
|
JOIN prod_talentia_finance.IFTW2FGHM_ZZPOR ZZPOR ON
|
|
ZZGEA.CORI = ZZPOR.CORI
|
|
;
|
|
|
|
INSERT INTO w_ZZGEA
|
|
SELECT
|
|
'ZHGEC'::text AS source,
|
|
0::bigint AS oid_GEC,
|
|
ZZGEA.CSTE,
|
|
ZZGEA.ETAB,
|
|
ZZGEA.CORI,
|
|
ZZPOR.JRNR,
|
|
ZZGEA.CORI AS JRNRCORI,
|
|
DNOR,
|
|
NPIE,
|
|
LECR,
|
|
SENS,
|
|
DTCT AS DTEC,
|
|
DTCT,
|
|
ZZGEA.CSTE||ZZGEA.ETAB AS ETAB_CTI,
|
|
CASE WHEN NCPT = CPTC THEN CPTC ELSE CPTC || '-' || NCPT END AS NCPT_CTI,
|
|
NCPT,
|
|
CASE WHEN NCPT = CPTC THEN '' ELSE NCPT END AS NCPTPART,
|
|
CPTC,
|
|
''::text AS CONT_CTI,
|
|
''::text AS CONT,
|
|
''::text AS CCTC,
|
|
CASE WHEN AXE0 <> '' THEN AXE0||'-0' ELSE '' END AS AXE0,
|
|
CASE WHEN AXE1 <> '' THEN AXE1||'-1' ELSE '' END AS AXE1,
|
|
CASE WHEN AXE2 <> '' THEN AXE2||'-2' ELSE '' END AS AXE2,
|
|
CASE WHEN AXE3 <> '' THEN AXE3||'-3' ELSE '' END AS AXE3,
|
|
CASE WHEN AXE4 <> '' THEN AXE4||'-4' ELSE '' END AS AXE4,
|
|
CASE WHEN AXE5 <> '' THEN AXE5||'-5' ELSE '' END AS AXE5,
|
|
CASE WHEN AXE6 <> '' THEN AXE6||'-6' ELSE '' END AS AXE6,
|
|
CASE WHEN AXE7 <> '' THEN AXE7||'-7' ELSE '' END AS AXE7,
|
|
CASE WHEN AXE8 <> '' THEN AXE8||'-8' ELSE '' END AS AXE8,
|
|
CASE WHEN AXE9 <> '' THEN AXE9||'-9' ELSE '' END AS AXE9,
|
|
CASE WHEN SENS = 'C' THEN MOA1 ELSE 0 END AS MOA1_C,
|
|
CASE WHEN SENS = 'D' THEN MOA1 ELSE 0 END AS MOA1_D
|
|
FROM prod_talentia_finance.IFTW2FGHM_ZHGEA ZZGEA
|
|
JOIN prod_talentia_finance.IFTW2FGHM_ZZPOR ZZPOR ON
|
|
ZZGEA.CORI = ZZPOR.CORI
|
|
WHERE DTCT >= 20140101
|
|
;
|
|
|
|
|
|
|
|
DROP TABLE IF EXISTS w_ZZGEA_GEC;
|
|
CREATE TEMP TABLE w_ZZGEA_GEC AS
|
|
SELECT source, CSTE, ETAB, NPIE, DNOR, CPTC, DTCT,
|
|
0::bigint AS oid_GEC,
|
|
SUM(MOA1_C) AS MOA1_C,
|
|
SUM(MOA1_D) AS MOA1_D
|
|
FROM w_ZZGEA
|
|
GROUP BY 1,2,3,4,5,6,7
|
|
ORDER BY 1,2,3,4,5,6,7
|
|
;
|
|
|
|
ANALYSE w_ZZGEA_GEC;
|
|
|
|
|
|
UPDATE w_ZZGEA ZZGEA
|
|
SET oid_GEC = subview.oid_GEC
|
|
FROM
|
|
(
|
|
SELECT ZZGEA.source, ZZGEA.CSTE, ZZGEA.ETAB, ZZGEA.NPIE, ZZGEA.DNOR, ZZGEA.DTCT, ZZGEA.CPTC, MAX(ZZGEC.oid) AS oid_GEC
|
|
FROM w_ZZGEA_GEC ZZGEA
|
|
JOIN w_ZZGEC ZZGEC ON
|
|
ZZGEA.source = ZZGEC.source AND
|
|
ZZGEA.CSTE = ZZGEC.CSTE AND
|
|
ZZGEA.ETAB = ZZGEC.ETAB AND
|
|
ZZGEA.CPTC = ZZGEC.CPTC AND
|
|
ZZGEA.DTCT = ZZGEC.DTCT AND
|
|
ZZGEA.NPIE = ZZGEC.NPIE AND
|
|
ZZGEA.DNOR = ZZGEC.DNOR
|
|
WHERE MON1_C - MON1_D = MOA1_C - MOA1_D
|
|
GROUP BY 1,2,3,4,5,6,7
|
|
HAVING count(*) = 1
|
|
) subview
|
|
WHERE ZZGEA.source = subview.source AND
|
|
ZZGEA.CSTE = subview.CSTE AND
|
|
ZZGEA.ETAB = subview.ETAB AND
|
|
ZZGEA.CPTC = subview.CPTC AND
|
|
ZZGEA.DTCT = subview.DTCT AND
|
|
ZZGEA.NPIE = subview.NPIE AND
|
|
ZZGEA.DNOR = subview.DNOR
|
|
;
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
DROP TABLE IF EXISTS w_ZZGEA_GEC;
|
|
CREATE TEMP TABLE w_ZZGEA_GEC AS
|
|
SELECT source, CSTE, ETAB, NPIE, CORI, DNOR, CPTC, DTCT,
|
|
0::bigint AS oid_GEC,
|
|
SUM(MOA1_C) AS MOA1_C,
|
|
SUM(MOA1_D) AS MOA1_D
|
|
FROM w_ZZGEA
|
|
WHERE oid_GEC = 0
|
|
GROUP BY 1,2,3,4,5,6,7,8
|
|
ORDER BY 1,2,3,4,5,6,7,8
|
|
;
|
|
|
|
ANALYSE w_ZZGEA_GEC;
|
|
|
|
|
|
UPDATE w_ZZGEA ZZGEA
|
|
SET oid_GEC = subview.oid_GEC
|
|
FROM
|
|
(
|
|
SELECT ZZGEA.source, ZZGEA.CSTE, ZZGEA.ETAB, ZZGEA.CORI, ZZGEA.NPIE, ZZGEA.DNOR, ZZGEA.DTCT, ZZGEA.CPTC, MAX(ZZGEC.oid) AS oid_GEC
|
|
FROM w_ZZGEA_GEC ZZGEA
|
|
JOIN w_ZZGEC ZZGEC ON
|
|
ZZGEA.source = ZZGEC.source AND
|
|
ZZGEA.CSTE = ZZGEC.CSTE AND
|
|
ZZGEA.ETAB = ZZGEC.ETAB AND
|
|
ZZGEA.CPTC = ZZGEC.CPTC AND
|
|
ZZGEA.CORI = ZZGEC.CORI AND
|
|
ZZGEA.DTCT = ZZGEC.DTCT AND
|
|
ZZGEA.NPIE = ZZGEC.NPIE AND
|
|
ZZGEA.DNOR = ZZGEC.DNOR
|
|
WHERE MON1_C - MON1_D = MOA1_C - MOA1_D
|
|
GROUP BY 1,2,3,4,5,6,7,8
|
|
HAVING count(*) = 1
|
|
) subview
|
|
WHERE ZZGEA.source = subview.source AND
|
|
ZZGEA.CSTE = subview.CSTE AND
|
|
ZZGEA.ETAB = subview.ETAB AND
|
|
ZZGEA.CPTC = subview.CPTC AND
|
|
ZZGEA.CORI = subview.CORI AND
|
|
ZZGEA.DTCT = subview.DTCT AND
|
|
ZZGEA.NPIE = subview.NPIE AND
|
|
ZZGEA.DNOR = subview.DNOR
|
|
;
|
|
|
|
|
|
UPDATE w_ZZGEA ZZGEA
|
|
SET SENS = ZZGEC.SENS,
|
|
MOA1_C = 0-MOA1_D,
|
|
MOA1_D = 0-MOA1_C
|
|
FROM w_ZZGEC ZZGEC
|
|
WHERE zzGEA.oid_GEC = zzGEC.oid AND
|
|
ZZGEC.sens <> ZZGEA.SENS
|
|
;
|
|
]]></sqlcmd>
|
|
</NODE>
|
|
|
|
|
|
<NODE label="Paramètres">
|
|
<sqlcmd><![CDATA[
|
|
|
|
INSERT INTO compta.t_sites(code_original, code, texte, clinique_honoraire)
|
|
SELECT CSTE||ETAB, CSTE||'-'||ETAB, LETA, 'C'
|
|
FROM prod_talentia_finance.IFTW2FGHM_ZZPLI
|
|
WHERE CSTE||ETAB NOT IN (SELECT code_original FROM compta.t_sites WHERE code_original IS NOT NULL)
|
|
ORDER BY CSTE||ETAB;
|
|
|
|
|
|
|
|
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);
|
|
|
|
DROP TABLE IF EXISTS w_ZZTPC;
|
|
CREATE TEMP TABLE w_ZZTPC AS
|
|
SELECT NCPT, TYPT::text, LCPT, substr(NCPT,1,2) AS TYPT_CTI
|
|
FROM prod_talentia_finance.IFTW2FGHM_ZZTPC
|
|
;
|
|
|
|
|
|
|
|
|
|
INSERT INTO compta.t_types_compta(code, code_original, texte, specialite)
|
|
SELECT TYPT_CTI,
|
|
TYPT_CTI,
|
|
MAX(
|
|
CASE
|
|
WHEN TYPT_CTI LIKE 'C%' THEN 'Clients ' || TYPT_CTI
|
|
WHEN TYPT_CTI LIKE 'F%' THEN 'Fournisseurs ' || TYPT_CTI
|
|
ELSE 'Autres' END),
|
|
MAX(CASE
|
|
WHEN TYPT_CTI LIKE 'C%' THEN 'CLI'
|
|
WHEN TYPT_CTI LIKE 'F%' THEN 'FOU'
|
|
ELSE '' END)
|
|
FROM w_ZZTPC
|
|
WHERE TYPT_CTI NOT IN (SELECT code_original FROM compta.t_types_compta WHERE code_original IS NOT NULL)
|
|
GROUP BY 1,2
|
|
;
|
|
|
|
|
|
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_original, code, texte)
|
|
SELECT AXE, AXE, LSEC
|
|
FROM
|
|
(
|
|
SELECT AXE0||'-0' AS AXE, LSEC
|
|
FROM prod_talentia_finance.IFTW2FGHM_ZZSA0
|
|
UNION
|
|
SELECT AXE1||'-1', LSEC
|
|
FROM prod_talentia_finance.IFTW2FGHM_ZZSA1
|
|
UNION
|
|
SELECT AXE2||'-2', LSEC
|
|
FROM prod_talentia_finance.IFTW2FGHM_ZZSA2
|
|
UNION
|
|
SELECT AXE3||'-3', LSEC
|
|
FROM prod_talentia_finance.IFTW2FGHM_ZZSA3
|
|
UNION
|
|
SELECT AXE4||'-4', LSEC
|
|
FROM prod_talentia_finance.IFTW2FGHM_ZZSA4
|
|
UNION
|
|
SELECT AXE5||'-5', LSEC
|
|
FROM prod_talentia_finance.IFTW2FGHM_ZZSA5
|
|
UNION
|
|
SELECT AXE6||'-6', LSEC
|
|
FROM prod_talentia_finance.IFTW2FGHM_ZZSA6
|
|
UNION
|
|
SELECT AXE7||'-7', LSEC
|
|
FROM prod_talentia_finance.IFTW2FGHM_ZZSA7
|
|
UNION
|
|
SELECT AXE8||'-8', LSEC
|
|
FROM prod_talentia_finance.IFTW2FGHM_ZZSA8
|
|
UNION
|
|
SELECT AXE9||'-9', LSEC
|
|
FROM prod_talentia_finance.IFTW2FGHM_ZZSA9
|
|
) subview
|
|
WHERE AXE NOT IN (SELECT code_original FROM compta.t_sections_analytiques WHERE code_original IS NOT NULL)
|
|
ORDER BY AXE
|
|
;
|
|
|
|
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_original, code, texte, texte_court)
|
|
SELECT NCPT, NCPT, LCPT, LCPT
|
|
FROM prod_talentia_finance.IFTW2FGHM_ZZTPC
|
|
WHERE NCPT NOT IN (SELECT code_original FROM compta.t_partenaires WHERE code_original IS NOT NULL)
|
|
ORDER BY NCPT;
|
|
|
|
|
|
|
|
|
|
INSERT INTO compta.t_journaux(oid, code, code_original, texte)
|
|
SELECT 0, chr(127) || '***', '', 'Non renseigné'
|
|
WHERE 0 NOT IN (SELECT oid FROM compta.t_journaux);
|
|
|
|
|
|
INSERT INTO compta.t_journaux(code, code_original, texte, a_nouveaux, clinique_honoraire)
|
|
SELECT JRNL, JRNL, LJNL,'0', 'C'
|
|
FROM prod_talentia_finance.IFTW2FGHM_ZZPJN
|
|
WHERE JRNL NOT IN (SELECT code_original FROM compta.t_journaux WHERE code_original IS NOT NULL)
|
|
ORDER BY JRNL;
|
|
|
|
INSERT INTO compta.t_journaux(code, code_original, texte, a_nouveaux, clinique_honoraire)
|
|
SELECT CORI, CORI, CASE WHEN LCOR NOT LIKE '*****%' THEN LCOR ELSE CORI END,'0', 'C'
|
|
FROM prod_talentia_finance.IFTW2FGHM_ZZPOR
|
|
WHERE IFTW2FGHM_ZZPOR.CORI NOT IN (SELECT code_original FROM compta.t_journaux WHERE code_original IS NOT NULL) AND
|
|
IFTW2FGHM_ZZPOR.CORI IN (SELECT CORI FROM w_ZZGEC)
|
|
ORDER BY 1;
|
|
|
|
INSERT INTO compta.t_journaux(code, code_original, texte, a_nouveaux, clinique_honoraire)
|
|
SELECT CORI, CORI, CASE WHEN LCOR NOT LIKE '*****%' THEN LCOR ELSE CORI END,'0', 'C'
|
|
FROM prod_talentia_finance.IFTW2FGHM_ZZPOR
|
|
WHERE IFTW2FGHM_ZZPOR.CORI NOT IN (SELECT code_original FROM compta.t_journaux WHERE code_original IS NOT NULL) AND
|
|
IFTW2FGHM_ZZPOR.CORI IN (SELECT CORI FROM w_ZZGEA)
|
|
ORDER BY 1;
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
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,
|
|
NCPT AS numero,
|
|
MAX(LCPT) AS texte,
|
|
0 AS compte_general_id,
|
|
'C' AS clinique_honoraire,
|
|
MAX(CASE WHEN NCPT LIKE '512%' IS NOT NULL THEN '1' ELSE '0' END) AS banque,
|
|
'0' AS collectif,
|
|
0 AS type_compta_extra_id,
|
|
'' AS numero_extra
|
|
FROM prod_talentia_finance.IFTW2FGHM_ZZGPC
|
|
LEFT JOIN compta.t_types_compta ON CASE WHEN NCPT LIKE '6%' OR NCPT LIKE '7%' OR NCPT LIKE '8%' OR NCPT LIKE '9%' THEN 'GES' ELSE 'BIL' END = t_types_compta.code_original
|
|
WHERE NCPT 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;
|
|
|
|
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,
|
|
NCPT_CTI AS numero,
|
|
MAX(ZZGPC.LCPT || ' - ' || ZZTPC.LCPT) AS texte,
|
|
MAX(t_comptes.oid) AS compte_general_id,
|
|
'C' AS clinique_honoraire,
|
|
'0' AS banque,
|
|
'0' AS collectif,
|
|
0 AS type_compta_extra_id,
|
|
'' AS numero_extra
|
|
FROM
|
|
(
|
|
SELECT ZZGEC.NCPT_CTI, CPTC, NCPT
|
|
FROM w_ZZGEC ZZGEC
|
|
WHERE NCPT <> CPTC
|
|
GROUP BY 1,2,3
|
|
) subview
|
|
JOIN prod_talentia_finance.IFTW2FGHM_ZZGPC ZZGPC ON subview.CPTC = ZZGPC.NCPT
|
|
JOIN w_ZZTPC ZZTPC ON subview.NCPT = ZZTPC.NCPT
|
|
JOIN compta.t_types_compta ON ZZTPC.TYPT_CTI = t_types_compta.code_original
|
|
JOIN compta.t_comptes ON CPTC = t_comptes.numero
|
|
WHERE NCPT_CTI NOT IN (SELECT numero FROM compta.t_comptes WHERE numero IS NOT NULL)
|
|
GROUP BY 1,2
|
|
ORDER BY 2
|
|
;
|
|
|
|
|
|
|
|
]]></sqlcmd>
|
|
</NODE>
|
|
|
|
</NODE>
|
|
|
|
</ROOT>
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|