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.
 
 
 

478 lines
17 KiB

<?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');
-- Pour l'instant, tout est remonté sans test
TRUNCATE compta.p_historique_ecritures;
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[
-- Oid de la section analytique dans l'écriture de compta gene
DROP TABLE IF EXISTS w_CMECRITURES;
CREATE TEMP TABLE w_CMECRITURES AS
SELECT CMECRITURES.*,
''::text AS ANA_ID
FROM prod_cegi.CMECRITURES
JOIN w_CMETABLISSEMENT ON CMECRITURES.DOS_ID = w_CMETABLISSEMENT.ETAB_ID
WHERE ecr_periode >= 200701 AND
ECR_NBDET = 0;
;
ANALYSE w_CMECRITURES
;
UPDATE w_CMECRITURES
SET ANA_ID = CMCODESANA.ANA_ID
FROM prod_cegi.CMCODESANA
WHERE ECR_CODANA = ANA_CODANA AND
ECR_CODANA <> '' AND
ECR_CODANA <> '*'
;
CREATE INDEX w_I_CMECRITURES_ECR_ID
ON w_CMECRITURES
USING btree
(ECR_ID)
;
CREATE INDEX w_I_CMECRITURES_PLC_COMPTE
ON w_CMECRITURES
USING btree
(PLC_COMPTE)
;
CREATE INDEX w_I_CMECRITURES_DOS_ID
ON w_CMECRITURES
USING btree
(DOS_ID)
;
CREATE INDEX w_I_CMECRITURES_JNL_CODE
ON w_CMECRITURES
USING btree
(JNL_CODE)
;
DROP TABLE IF EXISTS w_plx_plc;
CREATE TEMP TABLE w_plx_plc AS
SELECT plx_id, PLC_COMPTE, t_comptes.oid AS compte_id
FROM w_CMECRITURES CMECRITURES JOIN compta.t_comptes ON (cmecritures.plc_compte = t_comptes.numero)
JOIN w_CMETABLISSEMENT ON CMECRITURES.DOS_ID = w_CMETABLISSEMENT.ETAB_ID
WHERE plx_id <> 0
GROUP BY 1,2,3;
DROP TABLE IF EXISTS w_cpt_aux;
CREATE TEMP TABLE w_cpt_aux AS
SELECT cmplanaux.plx_id, 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_cegi.cmplanaux
JOIN w_plx_plc ON (cmplanaux.plx_id = w_plx_plc.plx_id)
JOIN compta.t_comptes ON (w_plx_plc.compte_id = t_comptes.oid)
JOIN compta.t_types_compta ON (auxi_typcpt = t_types_compta.code_original)
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,
ecr_datcpta AS date_ecriture,
ecr_periode AS mois_comptable,
CASE WHEN ecr_signed <> 1 THEN COALESCE(ECA_MONTANT, ecr_montant) ELSE 0 END AS montant_credit,
CASE WHEN ecr_signed = 1 THEN COALESCE(ECA_MONTANT, ecr_montant) ELSE 0 END AS montant_debit,
t_journaux.oid AS journal_id,
COALESCE(t_sections_analytiques.oid,0) AS section_analytique_id,
t_sites.clinique_honoraire,
ecr_periode / 100 AS exercice_comptable,
t_comptes.type_compta_id,
COALESCE(w_cpt_aux.compte_extra_id,t_comptes.oid),
'0' AS comptabilisee,
'0' AS fin_exercice,
'0' AS ajustement,
ecr_numecr::text || '-'::text || ecr_numord::text AS cle_originale,
COALESCE(t_comptes_contrep.oid,0) AS compte_contrepartie_id,
ecr_libelle || ' ' || ECR_LIBCOMPL AS texte,
'20991231' AS date_facture_fournisseur,
'' AS piece,
ecr_numfact AS dossier,
'20991231' 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,
ecr_numecr AS identifiant_operation
FROM w_CMECRITURES CMECRITURES
LEFT JOIN prod_cegi.CMECRANA ON CMECRANA.ECR_ID = CMECRITURES.ECR_ID
JOIN w_CMETABLISSEMENT ON CMECRITURES.DOS_ID = w_CMETABLISSEMENT.ETAB_ID
JOIN compta.t_comptes ON (cmecritures.plc_compte = t_comptes.numero)
JOIN compta.t_journaux ON (cmecritures.jnl_code = t_journaux.code_original)
JOIN compta.t_sites ON (cmecritures.dos_id = t_sites.code_original)
LEFT JOIN compta.t_sections_analytiques ON
COALESCE(CMECRANA.ANA_ID::text, CMECRITURES.ANA_ID::text) = t_sections_analytiques.code_original
LEFT JOIN w_cpt_aux ON (cmecritures.plx_id = w_cpt_aux.plx_id AND cmecritures.PLC_COMPTE = w_cpt_aux.PLC_COMPTE)
LEFT JOIN compta.t_comptes t_comptes_contrep ON (cmecritures.ecr_contrep = t_comptes_contrep.numero)
WHERE ecr_periode >= 200701 AND ecr_nbdet = 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">
<NODE label="Compléments écritures">
<sqlcmd><![CDATA[
]]></sqlcmd>
</NODE>
</NODE>
<NODE name="CHIFFRIER" label="CREATION DU CHIFFRIER">
<NODE label="Récupération chiffrier">
<sqlcmd><![CDATA[
]]></sqlcmd>
</NODE>
</NODE>
<NODE name="PARAM" label="RECUPERATION DES PARAMETRES">
<NODE label="Paramètres">
<sqlcmd><![CDATA[
-- 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);
-- Le code original devient l'oid
UPDATE compta.t_sections_analytiques
SET code_original = CMCODESANA.ANA_ID
FROM prod_cegi.CMCODESANA
WHERE code_original = CMCODESANA.ANA_CODANA AND
t_sections_analytiques.oid <> 0
;
INSERT INTO compta.t_sections_analytiques(code_original, code, texte)
SELECT
ANA_ID,
MAX(ANA_CODANA) AS code,
MAX(ANA_LIB) AS texte
FROM prod_cegi.CMCODESANA
WHERE ANA_CODANA <> '' AND
ANA_ID NOT IN (SELECT code_original FROM compta.t_sections_analytiques WHERE code_original IS NOT NULL)
GROUP BY 1;
UPDATE compta.t_sections_analytiques SET
code = ANA_CODANA,
texte = ANA_LIB
FROM prod_cegi.CMCODESANA
WHERE ANA_CODANA <> '' AND
ANA_ID = code_original AND
(
code IS DISTINCT FROM ANA_CODANA OR
texte IS DISTINCT FROM ANA_LIB
)
;
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
DROP TABLE IF EXISTS w_CMETABLISSEMENT;
CREATE TEMP TABLE w_CMETABLISSEMENT AS
SELECT *
FROM prod_cegi.CMETABLISSEMENT
WHERE ETAB_ID::text = ANY (string_to_array('[ETAB]'::text,',')) OR
'[ETAB]' = '';
INSERT INTO compta.t_sites(code_original, code, texte)
SELECT etab_id, etab_code, etab_lib
FROM w_CMETABLISSEMENT
WHERE etab_id IN (SELECT DISTINCT dos_id FROM prod_cegi.cmecritures)
AND etab_id 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, code_original, texte, specialite)
SELECT DISTINCT auxi_typcpt, auxi_typcpt, auxi_typcpt, '' FROM prod_cegi.cmplanaux
WHERE auxi_typcpt NOT IN (SELECT code_original FROM compta.t_types_compta);
-- Journaux
INSERT INTO compta.t_journaux(code, code_original, texte, a_nouveaux)
SELECT jnl_code, jnl_code, jnl_lib, CASE WHEN jnl_typj = 'N' THEN '1' ELSE '0' END
FROM prod_cegi.cmjournaux
WHERE jnl_code NOT IN (SELECT code_original FROM compta.t_journaux);
-- Partenaires
INSERT INTO compta.t_partenaires(code, code_original, texte, texte_court)
SELECT tie_code, tie_id, tie_nom, tie_nomc
FROM prod_cegi.cmtiers JOIN prod_cegi.cmplanaux ON (cmtiers.plx_id = cmplanaux.plx_id)
WHERE tie_id NOT IN (SELECT code_original FROM compta.t_partenaires)
ORDER BY tie_code;
-- Classes de comptes
-- Comptes
INSERT INTO compta.t_comptes (type_compta_id, numero, texte, clinique_honoraire, banque)
SELECT t_types_compta.oid, subview.plc_compte, subview.plc_libelle, '',
CASE WHEN subviewj.plc_compte IS NOT NULL THEN '1' ELSE '0' END
FROM
(SELECT
CASE WHEN cmplancpt.plc_compte LIKE '6%' THEN 'GES'
WHEN cmplancpt.plc_compte LIKE '7%' THEN 'GES'
WHEN cmplancpt.plc_compte LIKE '8%' THEN 'RES'
ELSE 'BIL' END AS plc_type,
cmplancpt.plc_compte,
cmplancpt.plc_libelle
FROM prod_cegi.cmplancpt) subview
JOIN compta.t_types_compta ON (plc_type = t_types_compta.code_original)
LEFT JOIN
(
SELECT DISTINCT plc_compte FROM prod_cegi.cmjournaux WHERE jnl_typj = 'T'
) subviewj ON (subviewj.plc_compte = subview.plc_compte)
WHERE subview.plc_compte NOT IN (SELECT numero FROM compta.t_comptes)
ORDER BY subview.plc_compte;
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 plx_id, t_comptes.oid AS compte_id
FROM prod_cegi.cmecritures JOIN compta.t_comptes ON (cmecritures.plc_compte = t_comptes.numero)
JOIN w_CMETABLISSEMENT ON CMECRITURES.DOS_ID = w_CMETABLISSEMENT.ETAB_ID
WHERE plx_id <> 0
GROUP BY 1,2;
INSERT INTO compta.t_comptes(
type_compta_id, numero, texte, compte_general_id, clinique_honoraire, partenaire_id)
SELECT t_types_compta.oid, t_comptes.numero::text || '_'::text || plx_compte::text, plx_libelle, t_comptes.oid, '', coalesce(t_partenaires.oid,0)
FROM prod_cegi.cmplanaux
JOIN w_plx_plc ON (cmplanaux.plx_id = w_plx_plc.plx_id)
JOIN compta.t_comptes ON (w_plx_plc.compte_id = t_comptes.oid)
JOIN compta.t_types_compta ON (auxi_typcpt = t_types_compta.code_original)
LEFT JOIN compta.t_partenaires ON (plx_idtiers = t_partenaires.code_original)
WHERE t_comptes.numero::text || '_'::text || plx_compte::text NOT IN (SELECT numero::text FROM compta.t_comptes);
-- 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>