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

735 lines
21 KiB

<?xml version="1.0" encoding="ISO-8859-1"?>
<ROOT>
<NODE name="PARAM" label="RECUPERATION DES PARAMETRES">
<NODE label="Regroupement des tables source">
<sqlcmd><![CDATA[
]]></sqlcmd>
</NODE>
<NODE label="Détection Mois modifiés">
<sqlcmd><![CDATA[
]]></sqlcmd>
</NODE>
<NODE label="Paramètres">
<sqlcmd><![CDATA[
-- Initialisation paramètres
UPDATE compta.t_classes_comptes SET code = '0', texte = 'Non renseigné' WHERE oid = 0;
INSERT INTO compta.t_classes_comptes(oid, code, texte, clinique, honoraire)
SELECT 0, '0', 'Non renseigné', '0', '0' WHERE 0 NOT IN (SELECT oid FROM compta.t_classes_comptes);
INSERT INTO compta.t_comptes(oid, type_compta_id, numero, texte, compte_general_id, clinique_honoraire)
SELECT 0, 0, '', 'Non renseigné', 0, '' WHERE 0 NOT IN (SElECT oid FROM compta.t_comptes);
INSERT INTO compta.t_types_compta(oid, code_original, code, texte)
SELECT 0, '', '', 'Non renseigné'
WHERE 0 NOT IN (SELECT oid FROM compta.t_types_compta);
-----------------------------------
------- Periode comptable --------
-----------------------------------
UPDATE base.p_calendrier_mois
SET exercice_mois_comptable_1 = subview.exercice_mois_comptable_1
FROM
(
SELECT exercice_comptable,
MIN(mois) AS exercice_mois_comptable_1
FROM base.p_calendrier_mois
GROUP BY 1
) subview
WHERE p_calendrier_mois.exercice_comptable = subview.exercice_comptable AND
p_calendrier_mois.exercice_mois_comptable_1 IS DISTINCT FROM subview.exercice_mois_comptable_1;
-------------------------
------- Sites ---------
-------------------------
INSERT INTO compta.t_sites(code_original, code, texte, clinique_honoraire)
SELECT DOS, DOS, MAX(NOM), 'C'
FROM prod_divalto.CA
WHERE DOS NOT IN (SELECT code_original FROM compta.t_sites WHERE code_original IS NOT NULL)
GROUP BY 1,2
;
UPDATE compta.t_sites SET
texte = NOM
FROM prod_divalto.CA
WHERE DOS = t_sites.code_original AND
(
t_sites.texte IS DISTINCT FROM NOM
)
;
----------------------------------
------- Types de compta ---------
----------------------------------
INSERT INTO compta.t_types_compta(code, code_original, texte, specialite)
SELECT * FROM
(
SELECT 'GES', 'GES' AS code_original, 'GESTION', 'GES'
UNION
SELECT 'BIL', 'BIL' AS code_original, 'BILAN', 'BIL'
UNION
SELECT 'RES', 'RES' AS code_original, 'RESULTAT', 'RES'
UNION
SELECT 'CLI', 'CLI' AS code_original, 'CLIENTS', 'CLI'
UNION
SELECT 'FOU', 'FOU' AS code_original, 'FOURNISSEURS', 'FOU'
UNION
SELECT 'MED', 'MED' AS code_original, 'MEDECINS', 'MED'
) subview
WHERE code_original NOT IN (SELECT code_original FROM compta.t_types_compta);
-----------------------------------------------
------- PREPA COMPTES ET PARTENAIRES --------
-----------------------------------------------
---- TABLE TEMPORAIRE QUI RECUPERE LES COMPTES ET PARTENAIRES
--- Le compte général est le numéro de compte (sans partenaire)
--- Le numéro de compte contient le numéro + partenaire (si présent)
--- Si pas de partenaires, les numéro de compte et général sont identiques
DROP TABLE IF EXISTS w_C3;
CREATE TEMP TABLE w_C3 AS (
SELECT
C3.DOS,
C3.CPT,
C3.C3_ID,
CASE WHEN C3.CPTCOL <> '' THEN C3.CPTCOL ELSE C3.CPT END AS CPT_NUMERO_GENERAL,
CASE WHEN C3.CPTCOL <> '' THEN C3.CPTCOL || '-' || C3.CPT ELSE C3.CPT END AS CPT_NUMERO,
CASE WHEN C3.CPTCOL <> '' THEN C3.CPT ELSE '' END AS CPT_PARTENAIRE,
CASE WHEN C3.CPTCOL <> '' THEN COALESCE(C3_COLL.LIB,C3.CPTCOL) || ' - ' || C3.LIB ELSE C3.LIB END AS CPT_LIB,
CASE WHEN C3.CPTCOL <> '' THEN C3.LIB ELSE '' END AS PARTENAIRE_LIB
FROM prod_divalto.C3
LEFT JOIN prod_divalto.C3 C3_COLL ON
C3.DOS = C3_COLL.DOS AND
C3.CPTCOL = C3_COLL.CPT
);
-- On rajoute le numéro de l'établissement si les noms sont différents entre établissements
UPDATE w_C3 SET
CPT_NUMERO = w_C3.CPT_NUMERO || '-' || w_C3.DOS,
CPT_PARTENAIRE = CASE WHEN CPT_PARTENAIRE <> '' THEN w_C3.CPT_PARTENAIRE || '-' || w_C3.DOS ELSE '' END
FROM
(
SELECT CPT_NUMERO, COUNT(DISTINCT CPT_LIB)
FROM w_C3
GROUP BY 1
HAVING count(DISTINCT CPT_LIB) > 1
) subview
WHERE w_C3.CPT_NUMERO = subview.CPT_NUMERO
;
UPDATE w_C3 SET
CPT_NUMERO_GENERAL = subview.CPT_NUMERO
FROM
(
SELECT DOS, CPT_NUMERO_GENERAL, CPT_NUMERO
FROM w_C3
WHERE cpt_partenaire = '' AND
CPT_NUMERO <> CPT_NUMERO_GENERAL
) subview
WHERE w_c3.DOS = subview.DOS AND
w_c3.CPT_NUMERO_GENERAL = subview.CPT_NUMERO_GENERAL
;
ANALYSE w_C3
;
DROP TABLE IF EXISTS w_compte;
CREATE TEMP TABLE w_compte AS
SELECT
CPT_NUMERO,
MAX(CPT_LIB) AS CPT_LIB,
MAX(CPT_NUMERO_GENERAL) AS CPT_NUMERO_GENERAL
FROM w_C3
GROUP BY 1
;
--------------------------
------- COMPTES --------
--------------------------
INSERT INTO compta.t_comptes (type_compta_id, numero, texte, clinique_honoraire, banque)
SELECT 0, CPT_NUMERO, CPT_LIB, 'C', CASE WHEN CPT_NUMERO LIKE '512%' THEN '1' ELSE '0' END AS banque
FROM w_compte
WHERE CPT_NUMERO_GENERAL = CPT_NUMERO AND
CPT_NUMERO NOT IN (SELECT numero FROM compta.t_comptes)
;
INSERT INTO compta.t_comptes (type_compta_id, numero, texte, clinique_honoraire, banque, compte_general_id)
SELECT 0, CPT_NUMERO, CPT_LIB, 'C' , CASE WHEN CPT_NUMERO LIKE '512%' THEN '1' ELSE '0' END AS banque, t_compte_general.oid
FROM w_compte
JOIN compta.t_comptes t_compte_general ON CPT_NUMERO_GENERAL = t_compte_general.numero
WHERE CPT_NUMERO_GENERAL <> CPT_NUMERO AND
CPT_NUMERO NOT IN (SELECT numero FROM compta.t_comptes)
;
UPDATE compta.t_comptes
SET compte_general_id = oid
WHERE oid <> 0 AND
(compte_general_id = 0 OR compte_general_id IS NULL)
;
UPDATE compta.t_comptes
SET texte = CPT_LIB
FROM w_compte
WHERE CPT_NUMERO = t_comptes.numero AND
(
t_comptes.texte IS DISTINCT FROM CPT_LIB
)
;
-------
---- Type de compta
-------
UPDATE compta.t_comptes
SET type_compta_id = t_types_compta.oid
FROM (
SELECT
oid,
CASE
WHEN numero LIKE '6%' THEN 'GES'
WHEN numero LIKE '7%' THEN 'GES'
WHEN numero LIKE '8%' THEN 'RES'
ELSE 'BIL'
END AS w_type_compta_code
FROM compta.t_comptes
) subview
JOIN compta.t_types_compta ON subview.w_type_compta_code = t_types_compta.code
WHERE subview.oid = t_comptes.oid AND
type_compta_id IS DISTINCT FROM t_types_compta.oid
;
-------
--- Type de compta extra
-------
UPDATE compta.t_comptes
SET type_compta_extra_id = t_comptes.type_compta_id
WHERE t_comptes.compte_general_id = t_comptes.oid AND
(
type_compta_extra_id IS DISTINCT FROM t_comptes.type_compta_id
)
;
UPDATE compta.t_comptes
SET type_compta_extra_id = t_types_compta.oid, type_compta_id = t_types_compta.oid
FROM (
SELECT
oid,
substr(numero,1,2),
CASE
WHEN numero LIKE '40%' THEN 'FOU'
WHEN numero LIKE '41%' THEN 'CLI'
WHEN numero LIKE '46%' THEN 'MED'
ELSE ''
END AS w_type_compta_code
FROM compta.t_comptes
WHERE compte_general_id <> oid
) subview
JOIN compta.t_types_compta ON subview.w_type_compta_code = t_types_compta.code
WHERE subview.oid = t_comptes.oid AND
(
type_compta_extra_id IS DISTINCT FROM t_types_compta.oid OR
type_compta_id IS DISTINCT FROM t_types_compta.oid
)
;
--------------------------------
-------- PARTENAIRES ---------
--------------------------------
INSERT INTO compta.t_partenaires(code, code_original, texte, texte_court)
SELECT CPT_PARTENAIRE, CPT_PARTENAIRE, MAX(PARTENAIRE_LIB),MAX(PARTENAIRE_LIB)
FROM w_C3
where CPT_PARTENAIRE <> ''
AND CPT_PARTENAIRE NOT IN (SELECT code_original FROM compta.t_partenaires)
GROUP BY 1
ORDER BY 1
;
UPDATE compta.t_partenaires SET
texte = PARTENAIRE_LIB,
texte_court = PARTENAIRE_LIB
FROM w_C3
WHERE CPT_PARTENAIRE = t_partenaires.code_original AND
(
t_partenaires.texte IS DISTINCT FROM PARTENAIRE_LIB OR
t_partenaires.texte_court IS DISTINCT FROM PARTENAIRE_LIB
)
;
----------------------------
------- JOURNAUX ---------
----------------------------
DROP TABLE IF EXISTS w_C4;
CREATE TEMP TABLE w_C4 AS (
SELECT
JNL AS JNL_CODE,
JNL AS JNL,
LIB AS JNL_LIB,
DOS,
CASE WHEN (JNL LIKE 'AN' OR JNL LIKE 'C10') THEN '1' ELSE '0' END AS a_nouveaux
FROM prod_divalto.C4
GROUP BY 1,2,3,4
);
-- On rajoute le numéro de l'établissement si les noms sont différents entre établissements
UPDATE w_C4 SET
JNL_CODE = w_C4.JNL_CODE || '-' || w_C4.DOS
FROM
(
SELECT JNL_CODE, COUNT(DISTINCT JNL_LIB)
FROM w_C4
GROUP BY 1
HAVING count(DISTINCT JNL_LIB) > 1
) subview
WHERE w_C4.JNL_CODE = subview.JNL_CODE
;
DROP TABLE IF EXISTS w_journaux;
CREATE TEMP TABLE w_journaux AS (
SELECT JNL_CODE, MAX(JNL_LIB) AS JNL_LIB, MAX(a_nouveaux) as a_nouveaux
FROM w_C4
GROUP BY 1
)
;
INSERT INTO compta.t_journaux(code, code_original, texte, a_nouveaux)
SELECT JNL_CODE, JNL_CODE, JNL_LIB, a_nouveaux
FROM w_journaux
WHERE JNL_CODE NOT IN (SELECT code_original FROM compta.t_journaux)
;
UPDATE compta.t_journaux SET
texte = JNL_LIB
FROM w_journaux
WHERE w_journaux.JNL_CODE = t_journaux.code_original AND
(
t_journaux.texte IS DISTINCT FROM JNL_LIB
)
;
-------------------------
------- CLASSES DE COMPTES
-------------------------
-------------------------
------- COMPTES GÉNÉRIQUES
-------------------------
----------------------------------------
-------- SECTIONS ANALYTIQUES --------
----------------------------------------
DROP TABLE IF EXISTS w_sections_analytiques;
CREATE TEMP TABLE w_sections_analytiques AS (
SELECT axeno || '-' || axe || '-' || dos as CODE_ANAL, LIB AS LIB_ANAL
FROM prod_divalto.C5
group by AXE, AXENO, DOS, LIB_ANAL
);
ANALYSE w_sections_analytiques;
INSERT INTO compta.t_sections_analytiques(code_original, code, texte)
SELECT
CODE_ANAL,
CODE_ANAL AS code,
LIB_ANAL AS texte
FROM w_sections_analytiques
WHERE CODE_ANAL NOT IN (SELECT code_original FROM compta.t_sections_analytiques WHERE code_original IS NOT NULL)
;
UPDATE compta.t_sections_analytiques SET
code = CODE_ANAL,
texte = LIB_ANAL
FROM w_sections_analytiques
WHERE CODE_ANAL = code_original AND
(
code IS DISTINCT FROM w_sections_analytiques.CODE_ANAL OR
texte IS DISTINCT FROM LIB_ANAL
)
;
-------------------------------------------------------------------
-- Comptes auxiliaires
-- comptes non présents
-- Classes de comptes
]]></sqlcmd>
</NODE>
</NODE>
<NODE name="INIT" label="INITIALISATIONS">
<NODE label="Détection Mois modifiés">
<sqlcmd><![CDATA[
-- Pour l'instant, tout est remonté sans test
]]></sqlcmd>
</NODE>
</NODE>
<NODE name="ECRITURES" label="RECUPERATION ECRITURES">
<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');
-- Pour l'instant, tout est remonté sans test, à terme ne remonter que le dernier exercice comptable
TRUNCATE compta.p_historique_ecritures;
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="Préparation">
<sqlcmd><![CDATA[
DROP TABLE IF EXISTS w_C8;
CREATE TEMP TABLE w_C8 AS (
SELECT
C8_ID,
ECRNO,
ECRDT,
ECRLG,
to_char(ECRDT, 'YYYYMM')::integer AS w_mois,
COALESCE(ECHDT , '20991231')::date as w_date_echeance,
PIECE,
C8.DOS,
w_C3.CPT_NUMERO,
w_C3.CPT_PARTENAIRE,
w_C3_CP.CPT_NUMERO AS CPT_NUMERO_CP,
w_C4.JNL_CODE,
CASE WHEN SENS = 1 THEN MT ELSE 0 END AS w_montant_debit,
CASE WHEN SENS = 2 THEN MT ELSE 0 END AS w_montant_credit,
LIB,
CHQNO
FROM prod_divalto.C8
JOIN w_C3 ON
C8.CPT = w_C3.CPT AND
C8.DOS = w_C3.DOS
LEFT JOIN w_C3 w_C3_CP ON
C8.CP = w_C3_CP.CPT AND
C8.DOS = w_C3_CP.DOS
JOIN w_C4 ON
C8.JNL = w_C4.JNL AND
C8.DOS = w_C4.DOS
);
ANALYSE w_C8
;
CREATE INDEX w_c8_iJNL ON w_C8 USING btree (JNL_CODE);
CREATE INDEX w_C8_iMOIS ON w_C8 USING btree (w_mois);
CREATE INDEX w_C8_iCPT ON w_C8 USING btree (CPT_NUMERO);
]]></sqlcmd>
</NODE> -->
<NODE label="Génération détail">
<sqlcmd><![CDATA[
INSERT INTO compta.p_historique_ecritures(
compte_id,
date_ecriture,
mois_comptable,
montant_credit,
montant_debit,
journal_id,
section_analytique_id,
clinique_honoraire,
exercice_comptable,
type_compta_id,
compte_extra_id,
comptabilisee,
fin_exercice,
ajustement,
cle_originale,
compte_contrepartie_id,
texte,
date_facture_fournisseur,
piece,
dossier,
date_echeance,
journal_paiement_id,
mode_paiement_id,
numero_cheque,
site_id,
partenaire_id,
inter_site,
identifiant_operation
)
SELECT
t_comptes.oid AS compte_id,
ECRDT AS date_ecriture,
mois AS mois_comptable,
w_montant_credit,
w_montant_debit,
t_journaux.oid AS journal_id,
0 AS section_analytique_id, -- REVOIR N
t_sites.clinique_honoraire,
exercice_comptable,
t_comptes.type_compta_id,
t_comptes.oid AS compte_extra_id,
'0' AS comptabilisee,
'0' AS fin_exercice,
'0' AS ajustement,
c8_id AS cle_originale,
COALESCE(t_comptes_contre.oid,0) AS compte_contrepartie_id,
lib AS texte,
'20991231' AS date_facture_fournisseur,
piece AS piece,
''::text AS dossier,
w_date_echeance as date_echeance,
0 AS journal_paiement_id,
0 AS mode_paiement_id,
COALESCE(chqno,'') AS numero_cheque,
t_sites.oid AS site_id,
COALESCE(t_partenaires.oid,0),
'0' AS inter_site,
w_C8.ECRNO::text || '.' || w_C8.ECRLG::text AS identifiant_operation
FROM w_C8
JOIN base.p_calendrier_mois ON w_mois = mois
JOIN compta.t_comptes ON CPT_NUMERO = t_comptes.numero
LEFT JOIN compta.t_comptes t_comptes_contre ON CPT_NUMERO_CP = t_comptes_contre.numero -- compte de contre-partie
JOIN compta.t_journaux ON JNL_CODE = t_journaux.code_original
JOIN compta.t_sites ON DOS = t_sites.code_original
LEFT JOIN compta.t_partenaires t_partenaires ON CPT_PARTENAIRE = t_partenaires.code_original
;
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">
<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;
-- Précision cli/hon (cli prioritaire)
UPDATE compta.t_comptes
SET clinique_honoraire = subview.clinique_honoraire
FROM
(
SELECT
compte_id AS compte_id,
MIN(CASE WHEN p_historique_ecritures.clinique_honoraire = 'H' THEN 'H' ELSE 'C' END) AS clinique_honoraire
FROM compta.p_historique_ecritures
JOIN compta.t_comptes ON compte_id = t_comptes.oid
GROUP BY 1
) subview
WHERE t_comptes.oid = subview.compte_id AND
t_comptes.clinique_honoraire <> subview.clinique_honoraire;
UPDATE compta.t_comptes
SET clinique_honoraire = subview.clinique_honoraire
FROM
(
SELECT
t_comptes.oid AS compte_id,
t_comptes.numero,
MIN(CASE WHEN p_historique_ecritures.clinique_honoraire = 'H' THEN 'H' ELSE 'C' END) AS clinique_honoraire
FROM compta.p_historique_ecritures
JOIN compta.t_comptes ON compte_extra_id = t_comptes.oid
GROUP BY 1,2
) subview
WHERE t_comptes.oid = subview.compte_id AND
t_comptes.clinique_honoraire <> subview.clinique_honoraire;
UPDATE compta.t_journaux
SET clinique_honoraire = subview.clinique_honoraire
FROM
(
SELECT
journal_id,
MIN(CASE WHEN p_historique_ecritures.clinique_honoraire = 'H' THEN 'H' ELSE 'C' END) AS clinique_honoraire
FROM compta.p_historique_ecritures
GROUP BY 1
) subview
WHERE t_journaux.oid = subview.journal_id AND
t_journaux.clinique_honoraire <> subview.clinique_honoraire;
]]></sqlcmd>
</NODE>
</NODE>
<NODE name="CHIFFRIER" label="CREATION DU CHIFFRIER">
<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
to_char(ECRDT,'YYYYMM')::numeric as mois_comptable,
t_sites.oid AS site_id,
'C' as clinique_honoraire,
SUM(CASE WHEN SENS = 1 THEN MT ELSE 0 END) AS w_montant_debit,
SUM(CASE WHEN SENS = 2 THEN MT ELSE 0 END) AS w_montant_credit
FROM prod_divalto.C8
JOIN compta.t_sites ON DOS = t_sites.code_original
GROUP BY 1,2,3
;
]]></sqlcmd>
</NODE>
</NODE>
</ROOT>