|
|
<?xml version="1.0" encoding="ISO-8859-1"?>
|
|
|
<ROOT>
|
|
|
|
|
|
|
|
|
<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');
|
|
|
|
|
|
-- periode en cours - 1 an (possibilité de modification de l'ancien exercice)
|
|
|
-- Pour l'instant désactivé, on prend tout
|
|
|
DROP TABLE IF EXISTS w_PERIODE;
|
|
|
CREATE TEMP TABLE w_PERIODE AS
|
|
|
SELECT
|
|
|
to_char(MIN(EX_DATEDEBUT),'YYYYMM')::bigint as date_debut_cegid,
|
|
|
date(MAX(EX_DATEFIN)) as date_fin_cegid
|
|
|
FROM prod_cegid.EXERCICE
|
|
|
WHERE EX_ETATCPTA = 'OUV' OR EX_ETATCPTA <> 'OUV'
|
|
|
;
|
|
|
|
|
|
-- vérification sur la date de debut données cegid
|
|
|
UPDATE w_periode SET
|
|
|
date_debut_cegid = GREATEST(date_debut_cegid,to_char(EX_DATEDEBUT,'YYYMM')::bigint)
|
|
|
FROM (SELECT MIN(EX_DATEDEBUT) AS EX_DATEDEBUT FROM prod_cegid.EXERCICE) sub
|
|
|
;
|
|
|
|
|
|
DELETE FROM compta.p_historique_ecritures
|
|
|
USING w_PERIODE
|
|
|
WHERE mois_comptable >= date_debut_cegid;
|
|
|
|
|
|
--TRUNCATE compta.p_historique_ecritures_total;
|
|
|
|
|
|
|
|
|
|
|
|
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_cpt;
|
|
|
CREATE TEMP TABLE w_cpt AS
|
|
|
SELECT COMPTE_PC, LIBELLE_PC, t_comptes.oid AS compte_id
|
|
|
FROM prod_cegid."0808377P" JOIN compta.t_comptes ON (COMPTE_PC = t_comptes.numero)
|
|
|
GROUP BY 1,2,3;
|
|
|
|
|
|
DROP TABLE IF EXISTS w_cpt_aux;
|
|
|
CREATE TEMP TABLE w_cpt_aux AS
|
|
|
SELECT PLC_COMPTE, t_types_compta.oid AS type_compte_extra_id, t_comptes_aux.oid AS compte_extra_id, coalesce(t_partenaires.oid,0) AS partenaire_id
|
|
|
FROM prod_cegid."0808377P"
|
|
|
JOIN compta.t_comptes ON (w_plx_plc.compte_id = t_comptes.oid)
|
|
|
JOIN compta.t_comptes t_comptes_aux ON (t_comptes.numero || '_'::text || plx_compte = t_comptes_aux.numero)
|
|
|
LEFT JOIN compta.t_partenaires ON (plx_idtiers = t_partenaires.code_original);
|
|
|
|
|
|
]]></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,
|
|
|
E_DATECOMPTABLE AS date_ecriture,
|
|
|
to_char(date_trunc('month',E_DATECOMPTABLE),'YYYYMM')::bigint AS mois_comptable,
|
|
|
E_CREDIT AS montant_credit,
|
|
|
E_DEBIT AS montant_debit,
|
|
|
t_journaux.oid AS journal_id,
|
|
|
0 AS section_analytique_id,
|
|
|
t_sites.clinique_honoraire,
|
|
|
to_char(date_trunc('month',E_DATECOMPTABLE),'YYYY')::bigint AS exercice_comptable,
|
|
|
t_comptes.type_compta_id,
|
|
|
COALESCE(w_cpt_aux.oid,t_comptes.oid),
|
|
|
'0' AS comptabilisee,
|
|
|
'0' AS fin_exercice,
|
|
|
'0' AS ajustement,
|
|
|
E_EXERCICE::text || E_NUMEROPIECE::text || to_char(E_NUMLIGNE,'0000') AS cle_originale,
|
|
|
COALESCE(t_comptes_contre.oid,0) AS compte_contrepartie_id,
|
|
|
E_LIBELLE AS texte,
|
|
|
'20991231' AS date_facture_fournisseur,
|
|
|
E_NUMEROPIECE AS piece,
|
|
|
'' AS dossier,
|
|
|
E_DATEECHEANCE AS date_echeance,
|
|
|
0 AS journal_paiement_id,
|
|
|
0 AS mode_paiement_id,
|
|
|
'' AS numero_cheque,
|
|
|
t_sites.oid AS site_id,
|
|
|
COALESCE(w_cpt_aux.partenaire_id,0),
|
|
|
'0' AS inter_site,
|
|
|
E_NUMEROPIECE::text || to_char(E_NUMLIGNE,'0000') AS identifiant_operation
|
|
|
FROM prod_cegid.ECRITURE
|
|
|
JOIN w_PERIODE ON E_PERIODE >= date_debut_cegid
|
|
|
JOIN compta.t_comptes ON (E_GENERAL = t_comptes.numero) AND compte_general_id = oid
|
|
|
JOIN compta.t_journaux ON (E_JOURNAL = t_journaux.code_original)
|
|
|
JOIN compta.t_sites ON (E_SOCIETE = t_sites.code)
|
|
|
LEFT JOIN compta.t_comptes w_cpt_aux ON (E_GENERAL || '_' || E_AUXILIAIRE = w_cpt_aux.numero)
|
|
|
LEFT JOIN compta.t_comptes t_comptes_contre ON t_comptes_contre.numero = CASE WHEN E_CONTREPARTIEAUX IS NOT NULL THEN E_CONTREPARTIEGEN || '_' || E_CONTREPARTIEAUX ELSE E_CONTREPARTIEGEN END
|
|
|
LEFT JOIN compta.t_mode_paiement ON E_MODEPAIE = t_mode_paiement.code_original
|
|
|
WHERE (E_LIBELLE NOT LIKE 'DETRUITE%' OR E_ECRANOUVEAU = 'OAN') AND E_QUALIFPIECE != 'S'
|
|
|
;
|
|
|
|
|
|
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 HONORAIRES (optionel)">
|
|
|
|
|
|
<condition><![CDATA[
|
|
|
SELECT count(*) > 0
|
|
|
FROM information_schema.tables
|
|
|
WHERE 1=1
|
|
|
AND table_schema = 'prod_cegid'
|
|
|
AND table_name = 'ecriture_hono'
|
|
|
;
|
|
|
|
|
|
]]></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');
|
|
|
|
|
|
-- Pour l'instant, tout est remonté sans test
|
|
|
--TRUNCATE compta.p_historique_ecritures;
|
|
|
DROP TABLE IF EXISTS w_PERIODE;
|
|
|
CREATE TEMP TABLE w_PERIODE AS
|
|
|
SELECT
|
|
|
oid AS societe_id,
|
|
|
to_char(MIN(EX_DATEDEBUT) - interval '3 year','YYYYMM')::bigint as date_debut_cegid,
|
|
|
MAX(EX_DATEFIN) as date_fin_cegid
|
|
|
FROM prod_cegid.EXERCICE_HONO
|
|
|
JOIN compta.t_sites ON code_original = EX_SOCIETE || '_H'
|
|
|
WHERE EX_ETATCPTA = 'OUV' OR EX_ETATCPTA <> 'OUV'
|
|
|
GROUP BY 1
|
|
|
;
|
|
|
|
|
|
DELETE FROM compta.p_historique_ecritures
|
|
|
USING w_PERIODE
|
|
|
WHERE mois_comptable >= date_debut_cegid
|
|
|
AND site_id = societe_id;
|
|
|
|
|
|
--TRUNCATE compta.p_historique_ecritures_total;
|
|
|
|
|
|
|
|
|
|
|
|
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(
|
|
|
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,
|
|
|
E_DATECOMPTABLE AS date_ecriture,
|
|
|
E_PERIODE AS mois_comptable,
|
|
|
E_CREDIT AS montant_credit,
|
|
|
E_DEBIT AS montant_debit,
|
|
|
t_journaux.oid AS journal_id,
|
|
|
0 AS section_analytique_id,
|
|
|
t_sites.clinique_honoraire,
|
|
|
E_PERIODE::bigint / 100 AS exercice_comptable,
|
|
|
t_comptes.type_compta_id,
|
|
|
COALESCE(w_cpt_aux.oid,t_comptes.oid),
|
|
|
'0' AS comptabilisee,
|
|
|
'0' AS fin_exercice,
|
|
|
'0' AS ajustement,
|
|
|
E_EXERCICE::text || E_NUMEROPIECE::text || to_char(E_NUMLIGNE,'0000') AS cle_originale,
|
|
|
COALESCE(t_comptes_contre.oid,0) AS compte_contrepartie_id,
|
|
|
E_LIBELLE AS texte,
|
|
|
'20991231' AS date_facture_fournisseur,
|
|
|
E_NUMEROPIECE AS piece,
|
|
|
'' AS dossier,
|
|
|
E_DATEECHEANCE AS date_echeance,
|
|
|
0 AS journal_paiement_id,
|
|
|
0 AS mode_paiement_id,
|
|
|
'' AS numero_cheque,
|
|
|
t_sites.oid AS site_id,
|
|
|
COALESCE(w_cpt_aux.partenaire_id,0),
|
|
|
'0' AS inter_site,
|
|
|
E_NUMEROPIECE::text || to_char(E_NUMLIGNE,'0000') AS identifiant_operation
|
|
|
FROM prod_cegid.ECRITURE_HONO ECRITURE
|
|
|
JOIN w_PERIODE ON E_PERIODE >= date_debut_cegid
|
|
|
JOIN compta.t_comptes ON (E_GENERAL = t_comptes.numero) AND compte_general_id = oid
|
|
|
JOIN compta.t_journaux ON (E_JOURNAL = t_journaux.code_original)
|
|
|
JOIN compta.t_sites ON (E_SOCIETE || '_H' = t_sites.code)
|
|
|
LEFT JOIN compta.t_comptes w_cpt_aux ON (E_GENERAL || '_' || E_AUXILIAIRE = w_cpt_aux.numero)
|
|
|
LEFT JOIN compta.t_comptes t_comptes_contre ON t_comptes_contre.numero = CASE WHEN E_CONTREPARTIEAUX IS NOT NULL THEN E_CONTREPARTIEGEN || '_' || E_CONTREPARTIEAUX ELSE E_CONTREPARTIEGEN END
|
|
|
LEFT JOIN compta.t_mode_paiement ON E_MODEPAIE = t_mode_paiement.code_original
|
|
|
WHERE (E_LIBELLE NOT LIKE 'DETRUITE%' OR E_ECRANOUVEAU = 'OAN') AND E_QUALIFPIECE != 'S'
|
|
|
;
|
|
|
|
|
|
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(UPG_DATPER,'YYYYMM')::bigint,
|
|
|
t_sites.oid AS site_id,
|
|
|
t_sites.clinique_honoraire,
|
|
|
SUM(UPG_DEBIT),
|
|
|
SUM(UPG_CREDIT)
|
|
|
FROM prod_cegid.CUMPERG
|
|
|
JOIN compta.t_sites ON (UPG_ETABLISSEMENT = t_sites.code)
|
|
|
GROUP BY 1,2,3
|
|
|
;
|
|
|
|
|
|
|
|
|
TRUNCATE compta.p_chiffrier_comptable_compte
|
|
|
;
|
|
|
|
|
|
INSERT INTO compta.p_chiffrier_comptable_compte
|
|
|
(
|
|
|
mois_comptable,
|
|
|
site_id,
|
|
|
compte_id,
|
|
|
clinique_honoraire,
|
|
|
montant_debit,
|
|
|
montant_credit
|
|
|
)
|
|
|
SELECT
|
|
|
to_char(UPG_DATPER,'YYYYMM')::bigint,
|
|
|
t_sites.oid AS site_id,
|
|
|
t_comptes.oid AS compte_id,
|
|
|
t_sites.clinique_honoraire,
|
|
|
SUM(UPG_DEBIT),
|
|
|
SUM(UPG_CREDIT)
|
|
|
FROM prod_cegid.CUMPERG
|
|
|
JOIN compta.t_comptes ON UPG_GENERAL = t_comptes.numero AND t_comptes.oid = t_comptes.compte_general_id
|
|
|
JOIN compta.t_sites ON (UPG_ETABLISSEMENT = t_sites.code)
|
|
|
GROUP BY 1,2,3
|
|
|
;
|
|
|
|
|
|
]]></sqlcmd>
|
|
|
</NODE>
|
|
|
|
|
|
<NODE label="Récupération chiffrier Honoraires">
|
|
|
<condition><![CDATA[
|
|
|
SELECT count(*) > 0
|
|
|
FROM information_schema.tables
|
|
|
WHERE 1=1
|
|
|
AND table_schema = 'prod_cegid'
|
|
|
AND table_name = 'ecriture_hono'
|
|
|
;
|
|
|
|
|
|
]]></condition>
|
|
|
<sqlcmd><![CDATA[
|
|
|
|
|
|
|
|
|
|
|
|
INSERT INTO compta.p_chiffrier_comptable
|
|
|
(
|
|
|
mois_comptable,
|
|
|
site_id,
|
|
|
clinique_honoraire,
|
|
|
montant_debit,
|
|
|
montant_credit
|
|
|
)
|
|
|
SELECT
|
|
|
to_char(UPG_DATPER,'YYYYMM')::bigint,
|
|
|
t_sites.oid AS site_id,
|
|
|
t_sites.clinique_honoraire,
|
|
|
SUM(UPG_DEBIT),
|
|
|
SUM(UPG_CREDIT)
|
|
|
FROM prod_cegid.CUMPERG_HONO
|
|
|
JOIN compta.t_sites ON (UPG_ETABLISSEMENT || '_H' = t_sites.code)
|
|
|
GROUP BY 1,2,3
|
|
|
;
|
|
|
|
|
|
INSERT INTO compta.p_chiffrier_comptable_compte
|
|
|
(
|
|
|
mois_comptable,
|
|
|
site_id,
|
|
|
compte_id,
|
|
|
clinique_honoraire,
|
|
|
montant_debit,
|
|
|
montant_credit
|
|
|
)
|
|
|
SELECT
|
|
|
to_char(UPG_DATPER,'YYYYMM')::bigint,
|
|
|
t_sites.oid AS site_id,
|
|
|
t_comptes.oid AS compte_id,
|
|
|
t_sites.clinique_honoraire,
|
|
|
SUM(UPG_DEBIT),
|
|
|
SUM(UPG_CREDIT)
|
|
|
FROM prod_cegid.CUMPERG
|
|
|
JOIN compta.t_comptes ON UPG_GENERAL = t_comptes.numero AND t_comptes.oid = t_comptes.compte_general_id
|
|
|
JOIN compta.t_sites ON (UPG_ETABLISSEMENT || '_H' = t_sites.code)
|
|
|
GROUP BY 1,2,3
|
|
|
;
|
|
|
|
|
|
]]></sqlcmd>
|
|
|
</NODE>
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
</NODE>
|
|
|
|
|
|
<NODE name="PARAM" label="RECUPERATION DES PARAMETRES">
|
|
|
|
|
|
<NODE label="Paramètres">
|
|
|
<sqlcmd><![CDATA[
|
|
|
|
|
|
-- Ajustement des types de compte généraux
|
|
|
UPDATE compta.t_comptes
|
|
|
SET type_compta_id = t_types_compta_ok.oid
|
|
|
FROM compta.t_types_compta,
|
|
|
compta.t_types_compta t_types_compta_ok
|
|
|
WHERE t_comptes.oid <> 0 AND
|
|
|
compte_general_id = t_comptes.oid AND
|
|
|
t_comptes.type_compta_id = t_types_compta.oid AND
|
|
|
t_types_compta_ok.code_original =
|
|
|
CASE
|
|
|
WHEN t_comptes.numero LIKE '6%' THEN 'GES'
|
|
|
WHEN t_comptes.numero LIKE '7%' THEN 'GES'
|
|
|
WHEN t_comptes.numero LIKE '8%' THEN 'RES'
|
|
|
ELSE 'BIL' END AND
|
|
|
type_compta_id <> t_types_compta_ok.oid
|
|
|
;
|
|
|
|
|
|
|
|
|
-- Periode comptable
|
|
|
UPDATE base.p_calendrier_mois SET
|
|
|
exercice_comptable = subview.exercice_comptable
|
|
|
FROM (
|
|
|
SELECT
|
|
|
p_calendrier_mois.mois,
|
|
|
p_calendrier_mois.date_debut,
|
|
|
date_part('year',p_calendrier_mois.date_debut) + CASE
|
|
|
WHEN to_number(substr(p_calendrier_mois.mois,5,2),'FM00') >= subview.exercice_mois_comptable_1 AND subview.exercice_mois_comptable_1 > 1 THEN 1
|
|
|
ELSE 0 END AS exercice_comptable
|
|
|
FROM base.p_calendrier_mois
|
|
|
JOIN (
|
|
|
SELECT
|
|
|
EX_DATEDEBUT,
|
|
|
EX_DATEFIN,
|
|
|
to_char(EX_DATEDEBUT,'YYYY') AS exercice_comptable,
|
|
|
to_char(EX_DATEDEBUT,'MM') AS exercice_mois_comptable_1
|
|
|
FROM
|
|
|
prod_cegid.EXERCICE
|
|
|
) subview ON 1 = 1
|
|
|
) subview
|
|
|
WHERE p_calendrier_mois.mois = subview.mois AND
|
|
|
p_calendrier_mois.exercice_comptable IS DISTINCT FROM subview.exercice_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;
|
|
|
|
|
|
-- Initialisation paramètres
|
|
|
UPDATE compta.t_sites SET code = chr(127) || '***', texte = 'Non renseigné' WHERE oid = 0;
|
|
|
INSERT INTO compta.t_sites(oid, code, clinique_honoraire, code_original, texte)
|
|
|
SELECT 0, chr(127) || '***', '', '', 'Non renseigné' WHERE 0 NOT IN (SELECT oid FROM compta.t_sites);
|
|
|
|
|
|
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);
|
|
|
|
|
|
UPDATE compta.t_partenaires SET code = chr(127) || '****', texte = 'Non renseigné', texte_court = 'Non renseigné' WHERE oid = 0;
|
|
|
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);
|
|
|
|
|
|
UPDATE compta.t_journaux SET code = chr(127) || '***', texte = 'Non renseigné' WHERE oid = 0;
|
|
|
INSERT INTO compta.t_journaux(oid, code, clinique_honoraire, code_original, texte)
|
|
|
SELECT 0, chr(127) || '***', '', '', 'Non renseigné' WHERE 0 NOT IN (SELECT oid FROM compta.t_journaux);
|
|
|
|
|
|
UPDATE compta.t_sections_analytiques SET code = chr(127) || '***', texte = 'Non renseigné' WHERE oid = 0;
|
|
|
INSERT INTO compta.t_sections_analytiques(oid, code, code_original, texte)
|
|
|
SELECT 0, chr(127) || '***', '', 'Non renseigné' 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_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);
|
|
|
|
|
|
-- Periode comptable
|
|
|
|
|
|
|
|
|
-- Sites
|
|
|
INSERT INTO compta.t_sites(code_original, code, texte, clinique_honoraire)
|
|
|
SELECT ET_ETABLISSEMENT, ET_ETABLISSEMENT, ET_LIBELLE, 'C'
|
|
|
FROM prod_cegid.ETABLISS
|
|
|
WHERE ET_ETABLISSEMENT IN (SELECT DISTINCT E_SOCIETE FROM prod_cegid.ECRITURE)
|
|
|
AND ET_ETABLISSEMENT NOT IN (SELECT code_original FROM compta.t_sites);
|
|
|
|
|
|
|
|
|
-- Types de compta
|
|
|
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);
|
|
|
|
|
|
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'
|
|
|
) subview
|
|
|
WHERE code_original NOT IN (SELECT code_original FROM compta.t_types_compta);
|
|
|
|
|
|
INSERT INTO compta.t_types_compta (code_original, code, texte, specialite)
|
|
|
SELECT T_NATUREAUXI,
|
|
|
T_NATUREAUXI,
|
|
|
CASE T_NATUREAUXI
|
|
|
WHEN 'FOU' THEN 'Fournisseur'
|
|
|
WHEN 'CLI' THEN 'Clients'
|
|
|
WHEN 'DIV' THEN 'Divers'
|
|
|
ELSE T_NATUREAUXI END,
|
|
|
CASE T_NATUREAUXI
|
|
|
WHEN 'FOU' THEN 'FOU'
|
|
|
WHEN 'CLI' THEN 'CLI'
|
|
|
WHEN 'DIV' THEN 'DIV'
|
|
|
ELSE 'DIV' END
|
|
|
FROM prod_cegid.TIERS
|
|
|
WHERE T_NATUREAUXI NOT IN (SELECT code_original FROM compta.t_types_compta)
|
|
|
GROUP BY 1,2,3,4
|
|
|
;
|
|
|
|
|
|
-- Journaux
|
|
|
INSERT INTO compta.t_journaux(code, code_original, texte, a_nouveaux)
|
|
|
SELECT J_JOURNAL, J_JOURNAL, J_LIBELLE, CASE WHEN J_NATUREJAL = 'ANO' THEN '1' ELSE '0' END
|
|
|
FROM prod_cegid.JOURNAL
|
|
|
WHERE J_JOURNAL NOT IN (SELECT code_original FROM compta.t_journaux);
|
|
|
|
|
|
-- Mode de paiement
|
|
|
INSERT INTO compta.t_mode_paiement(oid, code, code_original, texte)
|
|
|
SELECT 0, '**', '**', 'Non renseigné'
|
|
|
WHERE 0 NOT IN (SELECT oid FROM compta.t_mode_paiement);
|
|
|
|
|
|
INSERT INTO compta.t_mode_paiement(code, code_original, texte)
|
|
|
SELECT MP_MODEPAIE, MP_MODEPAIE, MP_LIBELLE
|
|
|
FROM prod_cegid.MODEPAIE
|
|
|
WHERE MP_MODEPAIE <> '' AND
|
|
|
MP_MODEPAIE NOT IN (SELECT code_original FROM compta.t_mode_paiement WHERE code_original IS NOT NULL)
|
|
|
ORDER BY 1;
|
|
|
|
|
|
|
|
|
-- Partenaires
|
|
|
INSERT INTO compta.t_partenaires(code, code_original, texte, texte_court)
|
|
|
SELECT T_TIERS, T_TIERS, MAX(T_LIBELLE), MAX(T_ABREGE)
|
|
|
FROM prod_cegid.TIERS
|
|
|
WHERE T_TIERS NOT IN (SELECT code_original FROM compta.t_partenaires)
|
|
|
AND T_TIERS IS NOT NULL
|
|
|
GROUP BY 1,2
|
|
|
ORDER BY 1,2;
|
|
|
|
|
|
-- Classes de comptes
|
|
|
|
|
|
-- Comptes génériques
|
|
|
INSERT INTO compta.t_comptes (type_compta_id, numero, texte, clinique_honoraire, banque)
|
|
|
SELECT t_types_compta.oid, subview.G_GENERAL, subview.G_LIBELLE, '',
|
|
|
CASE WHEN subviewj.J_CONTREPARTIE IS NOT NULL THEN '1' ELSE '0' END
|
|
|
FROM
|
|
|
(SELECT
|
|
|
CASE WHEN G_GENERAL LIKE '6%' THEN 'GES'
|
|
|
WHEN G_GENERAL LIKE '7%' THEN 'GES'
|
|
|
WHEN G_GENERAL LIKE '8%' THEN 'RES'
|
|
|
ELSE 'BIL' END AS plc_type,
|
|
|
G_GENERAL,
|
|
|
MAX(G_LIBELLE) AS G_LIBELLE
|
|
|
FROM prod_cegid.GENERAUX GROUP BY 1,2 ORDER BY 2) subview
|
|
|
JOIN compta.t_types_compta ON (plc_type = t_types_compta.code_original)
|
|
|
LEFT JOIN
|
|
|
(
|
|
|
SELECT DISTINCT J_CONTREPARTIE FROM prod_cegid.JOURNAL WHERE J_NATUREJAL = 'BQE'
|
|
|
) subviewj ON J_CONTREPARTIE = G_GENERAL
|
|
|
LEFT JOIN (SELECT E_GENERAL FROM prod_cegid.ECRITURE GROUP BY 1 order by 1) compte_util ON G_GENERAL = E_GENERAL
|
|
|
WHERE E_GENERAL IS NOT NULL AND subview.G_GENERAL NOT IN (SELECT numero FROM compta.t_comptes)
|
|
|
ORDER BY subview.G_GENERAL
|
|
|
;
|
|
|
|
|
|
UPDATE compta.t_comptes SET compte_general_id = oid WHERE compte_general_id IS NULL OR (compte_general_id = 0 AND oid <> 0);
|
|
|
|
|
|
-- Comptes auxiliaires
|
|
|
DROP TABLE IF EXISTS w_plx_plc;
|
|
|
CREATE TEMP TABLE w_plx_plc AS
|
|
|
SELECT T_COLLECTIF,
|
|
|
T_TIERS, T_NATUREAUXI AS plc_type,
|
|
|
t_types_compta.oid AS type_compta_id,
|
|
|
MAX(t_comptes.oid) AS compte_general_id,
|
|
|
MAX(T_COLLECTIF||'_'||T_TIERS) AS code_original
|
|
|
FROM prod_cegid.TIERS
|
|
|
JOIN compta.t_comptes ON T_COLLECTIF = t_comptes.numero AND t_comptes.oid = t_comptes.compte_general_id
|
|
|
JOIN compta.t_types_compta ON T_NATUREAUXI = t_types_compta.code_original
|
|
|
GROUP BY 1,2,3,4
|
|
|
order by 1,2,3,4
|
|
|
;
|
|
|
|
|
|
UPDATE compta.t_comptes
|
|
|
SET type_compta_id = w_plx_plc.type_compta_id
|
|
|
FROM w_plx_plc
|
|
|
WHERE t_comptes.numero = w_plx_plc.code_original AND
|
|
|
t_comptes.oid <> t_comptes.compte_general_id AND
|
|
|
t_comptes.type_compta_id <> w_plx_plc.type_compta_id
|
|
|
|
|
|
;
|
|
|
|
|
|
INSERT INTO compta.t_comptes(
|
|
|
type_compta_id,
|
|
|
numero,
|
|
|
texte,
|
|
|
compte_general_id,
|
|
|
clinique_honoraire,
|
|
|
partenaire_id)
|
|
|
SELECT w_plx_plc.type_compta_id,
|
|
|
w_plx_plc.code_original,
|
|
|
t_partenaires.texte,
|
|
|
w_plx_plc.compte_general_id,
|
|
|
'',
|
|
|
COALESCE(t_partenaires.oid,0)
|
|
|
FROM w_plx_plc
|
|
|
LEFT JOIN compta.t_partenaires ON (T_TIERS = t_partenaires.code_original)
|
|
|
WHERE w_plx_plc.code_original NOT IN (SELECT numero::text FROM compta.t_comptes);
|
|
|
|
|
|
-- comptes non présents
|
|
|
INSERT INTO compta.t_comptes(type_compta_id, numero, texte, clinique_honoraire, banque)
|
|
|
SELECT t_types_compta.oid, E_GENERAL, MAX(E_LIBELLE), '', 0
|
|
|
FROM prod_cegid.ECRITURE
|
|
|
JOIN compta.t_types_compta ON (CASE WHEN E_GENERAL LIKE '6%' THEN 'GES'
|
|
|
WHEN E_GENERAL LIKE '7%' THEN 'GES'
|
|
|
WHEN E_GENERAL LIKE '8%' THEN 'RES'
|
|
|
ELSE 'BIL' END = t_types_compta.code_original)
|
|
|
WHERE E_GENERAL NOT IN (SELECT numero::text FROM compta.t_comptes)
|
|
|
GROUP BY 1,2;
|
|
|
|
|
|
-- Classes de comptes
|
|
|
INSERT into compta.t_classes_comptes (code, texte)
|
|
|
(SELECT DISTINCT substr(numero, 1 , 1), '' FROM compta.t_comptes
|
|
|
WHERE compte_general_id = oid AND numero <> '' AND substr(numero, 1 , 1) NOT IN (SELECT code FROM compta.t_classes_comptes))
|
|
|
UNION
|
|
|
SELECT DISTINCT substr(numero, 1 , 2), '' FROM compta.t_comptes
|
|
|
WHERE compte_general_id = oid AND numero <> '' AND substr(numero, 1 , 2) NOT IN (SELECT code FROM compta.t_classes_comptes)
|
|
|
UNION
|
|
|
SELECT DISTINCT substr(numero, 1 , 3), '' FROM compta.t_comptes
|
|
|
WHERE compte_general_id = oid AND numero <> '' AND substr(numero, 1 , 3) NOT IN (SELECT code FROM compta.t_classes_comptes)
|
|
|
UNION
|
|
|
SELECT DISTINCT substr(numero, 1 , 4), '' FROM compta.t_comptes
|
|
|
WHERE compte_general_id = oid AND numero <> '' AND substr(numero, 1 , 4) NOT IN (SELECT code FROM compta.t_classes_comptes)
|
|
|
UNION
|
|
|
SELECT DISTINCT substr(numero, 1 , 5), '' FROM compta.t_comptes
|
|
|
WHERE compte_general_id = oid AND numero <> '' AND substr(numero, 1 , 5) NOT IN (SELECT code FROM compta.t_classes_comptes)
|
|
|
UNION
|
|
|
SELECT DISTINCT substr(numero, 1 , 6), '' FROM compta.t_comptes
|
|
|
WHERE compte_general_id = oid AND numero <> '' AND substr(numero, 1 , 6) NOT IN (SELECT code FROM compta.t_classes_comptes)
|
|
|
;
|
|
|
|
|
|
UPDATE compta.t_classes_comptes SET texte = '' WHERE texte IS NULL
|
|
|
|
|
|
]]></sqlcmd>
|
|
|
</NODE>
|
|
|
|
|
|
<NODE label="Paramètres honoraires (optionnel)">
|
|
|
|
|
|
<condition><![CDATA[
|
|
|
SELECT count(*) > 0
|
|
|
FROM information_schema.tables
|
|
|
WHERE 1=1
|
|
|
AND table_schema = 'prod_cegid'
|
|
|
AND table_name = 'ecriture_hono'
|
|
|
;
|
|
|
|
|
|
]]></condition>
|
|
|
|
|
|
|
|
|
<sqlcmd><![CDATA[
|
|
|
|
|
|
-- Site spécifique
|
|
|
INSERT INTO compta.t_sites(code_original, code, texte, clinique_honoraire)
|
|
|
SELECT ET_ETABLISSEMENT || '_H', ET_ETABLISSEMENT || '_H', ET_LIBELLE || '(honoraires)', 'H'
|
|
|
FROM prod_cegid.ETABLISS
|
|
|
WHERE ET_ETABLISSEMENT IN (SELECT DISTINCT E_SOCIETE FROM prod_cegid.ECRITURE_HONO)
|
|
|
AND ET_ETABLISSEMENT || '_H' NOT IN (SELECT code_original FROM compta.t_sites);
|
|
|
|
|
|
|
|
|
|
|
|
-- Journaux
|
|
|
INSERT INTO compta.t_journaux(code, code_original, texte, a_nouveaux)
|
|
|
SELECT J_JOURNAL, J_JOURNAL, J_LIBELLE, CASE WHEN J_NATUREJAL = 'ANO' THEN '1' ELSE '0' END
|
|
|
FROM prod_cegid.JOURNAL_HONO
|
|
|
WHERE J_JOURNAL NOT IN (SELECT code_original FROM compta.t_journaux);
|
|
|
|
|
|
|
|
|
-- Mode de paiement
|
|
|
INSERT INTO compta.t_mode_paiement(code, code_original, texte)
|
|
|
SELECT MP_MODEPAIE, MP_MODEPAIE, MP_LIBELLE
|
|
|
FROM prod_cegid.MODEPAIE_HONO
|
|
|
WHERE MP_MODEPAIE <> '' AND
|
|
|
MP_MODEPAIE NOT IN (SELECT code_original FROM compta.t_mode_paiement WHERE code_original IS NOT NULL)
|
|
|
ORDER BY 1;
|
|
|
|
|
|
-- Types auxiliaires
|
|
|
INSERT INTO compta.t_types_compta (code_original, code, texte, specialite)
|
|
|
SELECT T_NATUREAUXI,
|
|
|
T_NATUREAUXI,
|
|
|
CASE T_NATUREAUXI
|
|
|
WHEN 'FOU' THEN 'Fournisseur'
|
|
|
WHEN 'CLI' THEN 'Clients'
|
|
|
WHEN 'DIV' THEN 'Divers'
|
|
|
ELSE T_NATUREAUXI END,
|
|
|
CASE T_NATUREAUXI
|
|
|
WHEN 'FOU' THEN 'FOU'
|
|
|
WHEN 'CLI' THEN 'CLI'
|
|
|
WHEN 'DIV' THEN 'DIV'
|
|
|
ELSE 'DIV' END
|
|
|
FROM prod_cegid.TIERS_HONO
|
|
|
WHERE T_NATUREAUXI NOT IN (SELECT code_original FROM compta.t_types_compta)
|
|
|
GROUP BY 1,2,3,4
|
|
|
;
|
|
|
|
|
|
-- Partenaires
|
|
|
INSERT INTO compta.t_partenaires(code, code_original, texte, texte_court)
|
|
|
SELECT T_TIERS, T_TIERS, MAX(T_LIBELLE), MAX(T_ABREGE)
|
|
|
FROM prod_cegid.TIERS_HONO
|
|
|
WHERE T_TIERS NOT IN (SELECT code_original FROM compta.t_partenaires)
|
|
|
AND T_TIERS IS NOT NULL
|
|
|
GROUP BY 1,2
|
|
|
ORDER BY 1,2;
|
|
|
|
|
|
-- Classes de comptes
|
|
|
|
|
|
-- Comptes génériques
|
|
|
INSERT INTO compta.t_comptes (type_compta_id, numero, texte, clinique_honoraire, banque)
|
|
|
SELECT t_types_compta.oid, subview.G_GENERAL, subview.G_LIBELLE, '',
|
|
|
CASE WHEN subviewj.J_CONTREPARTIE IS NOT NULL THEN '1' ELSE '0' END
|
|
|
FROM
|
|
|
(SELECT
|
|
|
CASE WHEN G_GENERAL LIKE '6%' THEN 'GES'
|
|
|
WHEN G_GENERAL LIKE '7%' THEN 'GES'
|
|
|
WHEN G_GENERAL LIKE '8%' THEN 'RES'
|
|
|
ELSE 'BIL' END AS plc_type,
|
|
|
G_GENERAL,
|
|
|
MAX(G_LIBELLE) AS G_LIBELLE
|
|
|
FROM prod_cegid.GENERAUX_HONO GROUP BY 1,2 ORDER BY 2) subview
|
|
|
JOIN compta.t_types_compta ON (plc_type = t_types_compta.code_original)
|
|
|
LEFT JOIN
|
|
|
(
|
|
|
SELECT DISTINCT J_CONTREPARTIE FROM prod_cegid.JOURNAL_HONO WHERE J_NATUREJAL = 'BQE'
|
|
|
) subviewj ON J_CONTREPARTIE = G_GENERAL
|
|
|
LEFT JOIN (SELECT E_GENERAL FROM prod_cegid.ECRITURE_HONO GROUP BY 1 order by 1) compte_util ON G_GENERAL = E_GENERAL
|
|
|
WHERE E_GENERAL IS NOT NULL AND subview.G_GENERAL NOT IN (SELECT numero FROM compta.t_comptes)
|
|
|
ORDER BY subview.G_GENERAL
|
|
|
;
|
|
|
|
|
|
UPDATE compta.t_comptes SET compte_general_id = oid WHERE compte_general_id IS NULL OR (compte_general_id = 0 AND oid <> 0);
|
|
|
|
|
|
-- Comptes auxiliaires
|
|
|
DROP TABLE IF EXISTS w_plx_plc;
|
|
|
CREATE TEMP TABLE w_plx_plc AS
|
|
|
SELECT T_COLLECTIF,
|
|
|
T_TIERS, T_NATUREAUXI AS plc_type,
|
|
|
t_types_compta.oid AS type_compta_id,
|
|
|
MAX(t_comptes.oid) AS compte_general_id,
|
|
|
MAX(T_COLLECTIF||'_'||T_TIERS) AS code_original
|
|
|
FROM prod_cegid.TIERS_HONO
|
|
|
JOIN compta.t_comptes ON T_COLLECTIF = t_comptes.numero AND t_comptes.oid = t_comptes.compte_general_id
|
|
|
JOIN compta.t_types_compta ON T_NATUREAUXI = t_types_compta.code_original
|
|
|
GROUP BY 1,2,3,4
|
|
|
order by 1,2,3,4
|
|
|
;
|
|
|
|
|
|
UPDATE compta.t_comptes
|
|
|
SET type_compta_id = w_plx_plc.type_compta_id
|
|
|
FROM w_plx_plc
|
|
|
WHERE t_comptes.numero = w_plx_plc.code_original AND
|
|
|
t_comptes.oid <> t_comptes.compte_general_id AND
|
|
|
t_comptes.type_compta_id <> w_plx_plc.type_compta_id
|
|
|
|
|
|
;
|
|
|
|
|
|
INSERT INTO compta.t_comptes(
|
|
|
type_compta_id,
|
|
|
numero,
|
|
|
texte,
|
|
|
compte_general_id,
|
|
|
clinique_honoraire,
|
|
|
partenaire_id)
|
|
|
SELECT w_plx_plc.type_compta_id,
|
|
|
w_plx_plc.code_original,
|
|
|
t_partenaires.texte,
|
|
|
w_plx_plc.compte_general_id,
|
|
|
'',
|
|
|
COALESCE(t_partenaires.oid,0)
|
|
|
FROM w_plx_plc
|
|
|
LEFT JOIN compta.t_partenaires ON (T_TIERS = t_partenaires.code_original)
|
|
|
WHERE w_plx_plc.code_original NOT IN (SELECT numero::text FROM compta.t_comptes);
|
|
|
|
|
|
|
|
|
|
|
|
-- comptes non présents
|
|
|
INSERT INTO compta.t_comptes(type_compta_id, numero, texte, clinique_honoraire, banque)
|
|
|
SELECT t_types_compta.oid, E_GENERAL, MAX(E_LIBELLE), '', 0
|
|
|
FROM prod_cegid.ECRITURE_HONO
|
|
|
JOIN compta.t_types_compta ON (CASE WHEN E_GENERAL LIKE '6%' THEN 'GES'
|
|
|
WHEN E_GENERAL LIKE '7%' THEN 'GES'
|
|
|
WHEN E_GENERAL LIKE '8%' THEN 'RES'
|
|
|
ELSE 'BIL' END = t_types_compta.code_original)
|
|
|
WHERE E_GENERAL NOT IN (SELECT numero::text FROM compta.t_comptes)
|
|
|
GROUP BY 1,2;
|
|
|
|
|
|
-- Classes de comptes
|
|
|
INSERT into compta.t_classes_comptes (code, texte)
|
|
|
(SELECT DISTINCT substr(numero, 1 , 1), '' FROM compta.t_comptes
|
|
|
WHERE compte_general_id = oid AND numero <> '' AND substr(numero, 1 , 1) NOT IN (SELECT code FROM compta.t_classes_comptes))
|
|
|
UNION
|
|
|
SELECT DISTINCT substr(numero, 1 , 2), '' FROM compta.t_comptes
|
|
|
WHERE compte_general_id = oid AND numero <> '' AND substr(numero, 1 , 2) NOT IN (SELECT code FROM compta.t_classes_comptes)
|
|
|
UNION
|
|
|
SELECT DISTINCT substr(numero, 1 , 3), '' FROM compta.t_comptes
|
|
|
WHERE compte_general_id = oid AND numero <> '' AND substr(numero, 1 , 3) NOT IN (SELECT code FROM compta.t_classes_comptes)
|
|
|
UNION
|
|
|
SELECT DISTINCT substr(numero, 1 , 4), '' FROM compta.t_comptes
|
|
|
WHERE compte_general_id = oid AND numero <> '' AND substr(numero, 1 , 4) NOT IN (SELECT code FROM compta.t_classes_comptes)
|
|
|
UNION
|
|
|
SELECT DISTINCT substr(numero, 1 , 5), '' FROM compta.t_comptes
|
|
|
WHERE compte_general_id = oid AND numero <> '' AND substr(numero, 1 , 5) NOT IN (SELECT code FROM compta.t_classes_comptes)
|
|
|
UNION
|
|
|
SELECT DISTINCT substr(numero, 1 , 6), '' FROM compta.t_comptes
|
|
|
WHERE compte_general_id = oid AND numero <> '' AND substr(numero, 1 , 6) NOT IN (SELECT code FROM compta.t_classes_comptes)
|
|
|
;
|
|
|
|
|
|
UPDATE compta.t_classes_comptes SET texte = '' WHERE texte IS NULL
|
|
|
|
|
|
]]></sqlcmd>
|
|
|
</NODE>
|
|
|
</NODE>
|
|
|
|
|
|
</ROOT>
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|