|
|
<?xml version="1.0" encoding="ISO-8859-1"?>
|
|
|
<ROOT>
|
|
|
|
|
|
|
|
|
<NODE name="INIT" label="INITIALISATIONS">
|
|
|
|
|
|
<NODE label="Détection Mois modifiés">
|
|
|
<sqlcmd><![CDATA[
|
|
|
|
|
|
-- Prise en compte des situations antérieures annulées
|
|
|
UPDATE prod_sigems.ECRIT_COMPTA
|
|
|
SET ECR_ANNUL = ''
|
|
|
FROM prod_sigems.JNAL
|
|
|
WHERE ECR_JNAL = JNAL.CODEJ AND
|
|
|
JNAL.TYP = 'S' AND
|
|
|
ECR_ANNUL = 'S' AND
|
|
|
ECR_FOLIO <> 0 AND
|
|
|
JNAL.CODEJ NOT IN (SELECT code_original FROM compta.t_journaux WHERE report_automatique_mois_suivant = '9');
|
|
|
|
|
|
|
|
|
-- Ecritures CTI
|
|
|
DROP TABLE IF EXISTS w_historique_ecritures_total;
|
|
|
CREATE TEMP TABLE w_historique_ecritures_total AS
|
|
|
SELECT mois_comptable,
|
|
|
t_comptes.numero as compte_numero_extra,
|
|
|
SUM(CASE WHEN ajustement = '0' THEN montant_debit ELSE 0 END) as debit,
|
|
|
SUM(CASE WHEN ajustement = '0' THEN montant_credit ELSE 0 END) as credit,
|
|
|
SUM(CASE WHEN ajustement = '2' THEN montant_debit ELSE 0 END) as debit_ajustement,
|
|
|
SUM(CASE WHEN ajustement = '2' THEN montant_credit ELSE 0 END) as credit_ajustement,
|
|
|
SUM(nombre_ecritures) as count
|
|
|
FROM compta.p_historique_ecritures_total
|
|
|
JOIN compta.t_comptes ON p_historique_ecritures_total.compte_extra_id = t_comptes.oid
|
|
|
WHERE mois_comptable >= 200801 AND ajustement IN ('0','2') AND
|
|
|
is_budget IS DISTINCT FROM '1'
|
|
|
GROUP BY 1,2
|
|
|
ORDER BY 1,2;
|
|
|
|
|
|
-- Ecritures prestataire
|
|
|
DROP TABLE IF EXISTS w_ECRIT;
|
|
|
CREATE TEMP TABLE w_ECRIT AS
|
|
|
SELECT
|
|
|
ECRIT_COMPTA.*,
|
|
|
COALESCE(ECRIT_COMPTALIBEL.ECR_LIBEL,'') AS ECR_LIBEL,
|
|
|
ECRIT_COMPTA.ECR_STE||'-'||ECRIT_COMPTA.ECR_AGE AS site_code,
|
|
|
date_part('year',ECRIT_COMPTA.ECR_DATE) * 100 + date_part('month',ECRIT_COMPTA.ECR_DATE) AS mois_comptable,
|
|
|
CASE WHEN ECRIT_COMPTA.ECR_CEMT = '' AND ECRIT_COMPTA.ECR_CEMT <> ECRIT_COMPTA.ECR_CPTE THEN ECRIT_COMPTA.ECR_CPTE ELSE ECRIT_COMPTA.ECR_CEMT END AS compte_numero,
|
|
|
CASE WHEN ECRIT_COMPTA.ECR_CEMT = '' AND ECRIT_COMPTA.ECR_CEMT <> ECRIT_COMPTA.ECR_CPTE THEN ECRIT_COMPTA.ECR_CPTE ELSE ECRIT_COMPTA.ECR_CEMT || '-' || ECRIT_COMPTA.ECR_CPTE END AS compte_numero_extra,
|
|
|
CASE WHEN ECRIT_COMPTA.ECR_CEMT = '' THEN '' ELSE ECRIT_COMPTA.ECR_PLAN || ECRIT_COMPTA.ECR_CPTE END AS partenaire_code,
|
|
|
'C'::text AS ECR_SRC,
|
|
|
COALESCE(ECRIT_COMPTAANA.ECR_CPTE, '') AS ECR_SANA,
|
|
|
COALESCE(ECRIT_COMPTAANA.ECR_CREDIT, ECRIT_COMPTA.ECR_CREDIT) AS ECR_CREDIT_ANA,
|
|
|
COALESCE(ECRIT_COMPTAANA.ECR_DEBIT, ECRIT_COMPTA.ECR_DEBIT) AS ECR_DEBIT_ANA,
|
|
|
JNAL.TYP AS JNAL_TYP,
|
|
|
JNAL.CODEJ AS JNAL_CODEJ,
|
|
|
JNAL.REFBASE AS JNAL_REFBASE,
|
|
|
''::text AS compte_numero_contre
|
|
|
FROM prod_sigems.ECRIT_COMPTA
|
|
|
JOIN w_STE ON ECRIT_COMPTA.ECR_STE || CASE WHEN '[SITES]' = '' THEN '' ELSE '-' || ECRIT_COMPTA.ECR_AGE END = SEL_STE
|
|
|
JOIN prod_sigems.JNAL ON ECRIT_COMPTA.ECR_JNAL = JNAL.CODEJ
|
|
|
LEFT JOIN prod_sigems.ECRIT_COMPTALIBEL ON ECRIT_COMPTA.ECR_NUM = ECRIT_COMPTALIBEL.ECR_NUM
|
|
|
LEFT JOIN prod_sigems.ECRIT_COMPTAANA ON ECRIT_COMPTA.ECR_NUM = ECRIT_COMPTAANA.ECR_NEMET AND
|
|
|
ECRIT_COMPTAANA.ECR_ANNUL <> 'S'
|
|
|
WHERE ECRIT_COMPTA.ECR_DATE >= '20100101' AND
|
|
|
ECRIT_COMPTA.ECR_ANNUL <> 'T' AND
|
|
|
ECRIT_COMPTA.ECR_ANNUL <> 'S' AND
|
|
|
ECRIT_COMPTA.ECR_PIECE <> 'CENTRALI' AND
|
|
|
ECRIT_COMPTA.ECR_PLAN NOT IN ('A');
|
|
|
|
|
|
-- Ajustement ecarts analytiques
|
|
|
DROP TABLE IF EXISTS w_ECRIT_ecartana;
|
|
|
CREATE TEMP TABLE w_ECRIT_ecartana AS
|
|
|
SELECT ECR_NUM, count(*) AS nb_ana, MAX(ECR_CREDIT) - SUM(ECR_CREDIT_ANA) AS ECR_CREDIT_ecart, MAX(ECR_DEBIT) - SUM(ECR_DEBIT_ANA) AS ECR_DEBIT_ecart
|
|
|
FROM w_ECRIT
|
|
|
GROUP BY 1
|
|
|
HAVING (
|
|
|
SUM(ECR_CREDIT_ANA) IS DISTINCT FROM MAX(ECR_CREDIT) OR
|
|
|
SUM(ECR_DEBIt_ANA) IS DISTINCT FROM MAX(ECR_DEBIt)
|
|
|
) ;
|
|
|
|
|
|
UPDATE w_ECRIT SET
|
|
|
ECR_CREDIT_ANA = ECR_CREDIT,
|
|
|
ECR_DEBIT_ANA = ECr_DEBIT
|
|
|
FROM w_ECRIT_ecartana
|
|
|
WHERE w_ECRIT_ecartana.ECR_NUM = w_ECRIT.ECR_NUM AND
|
|
|
nb_ana = 1
|
|
|
;
|
|
|
|
|
|
INSERT INTO w_ECRIT
|
|
|
SELECT
|
|
|
ECRIT_COMPTA.*,
|
|
|
COALESCE(ECRIT_COMPTALIBEL.ECR_LIBEL,'') AS ECR_LIBEL,
|
|
|
ECRIT_COMPTA.ECR_STE||'-'||ECRIT_COMPTA.ECR_AGE AS site_code,
|
|
|
date_part('year',ECRIT_COMPTA.ECR_DATE) * 100 + date_part('month',ECRIT_COMPTA.ECR_DATE) AS mois_comptable,
|
|
|
CASE WHEN ECRIT_COMPTA.ECR_CEMT = '' AND ECRIT_COMPTA.ECR_CEMT <> ECRIT_COMPTA.ECR_CPTE THEN ECRIT_COMPTA.ECR_CPTE ELSE ECRIT_COMPTA.ECR_CEMT END AS compte_numero,
|
|
|
CASE WHEN ECRIT_COMPTA.ECR_CEMT = '' AND ECRIT_COMPTA.ECR_CEMT <> ECRIT_COMPTA.ECR_CPTE THEN ECRIT_COMPTA.ECR_CPTE ELSE ECRIT_COMPTA.ECR_CEMT || '-' || ECRIT_COMPTA.ECR_CPTE END AS compte_numero_extra,
|
|
|
CASE WHEN ECRIT_COMPTA.ECR_CEMT = '' THEN '' ELSE ECRIT_COMPTA.ECR_PLAN || ECRIT_COMPTA.ECR_CPTE END AS partenaire_code,
|
|
|
'C'::text AS ECR_SRC,
|
|
|
COALESCE('') AS ECR_SANA,
|
|
|
ECR_CREDIT_ecart AS ECR_CREDIT_ANA,
|
|
|
ECR_DEBIT_ecart AS ECR_DEBIT_ANA,
|
|
|
JNAL.TYP AS JNAL_TYP,
|
|
|
JNAL.CODEJ AS JNAL_CODEJ,
|
|
|
JNAL.REFBASE AS JNAL_REFBASE,
|
|
|
''::text AS compte_numero_contre
|
|
|
FROM prod_sigems.ECRIT_COMPTA
|
|
|
JOIN w_ECRIT_ecartana ON w_ECRIT_ecartana.ECR_NUM = ECRIT_COMPTA.ECR_NUM AND nb_ana > 1
|
|
|
JOIN prod_sigems.JNAL ON ECRIT_COMPTA.ECR_JNAL = JNAL.CODEJ
|
|
|
LEFT JOIN prod_sigems.ECRIT_COMPTALIBEL ON ECRIT_COMPTA.ECR_NUM = ECRIT_COMPTALIBEL.ECR_NUM
|
|
|
;
|
|
|
|
|
|
UPDATE w_ECRIT SET
|
|
|
ECR_CREDIT = ECR_CREDIT_ANA,
|
|
|
ECR_DEBIT = ECR_DEBIT_ANA
|
|
|
WHERE ECR_CREDIT <> ECR_CREDIT_ANA OR
|
|
|
ECR_DEBIT <> ECR_DEBIT_ANA;
|
|
|
|
|
|
|
|
|
-- Extourne des écritures de situation
|
|
|
DROP TABLE IF EXISTS w_mois;
|
|
|
CREATE TEMP TABLE w_mois AS
|
|
|
SELECT
|
|
|
exercice_comptable,
|
|
|
mois,
|
|
|
date_part('year',date(mois||'01') + interval '1 month') * 100 + date_part('month',date(mois||'01') + interval '1 month') AS mois_suivant,
|
|
|
exercice_mois_comptable_1
|
|
|
FROM base.p_calendrier_mois;
|
|
|
|
|
|
UPDATE w_mois
|
|
|
SET mois_suivant = mois
|
|
|
WHERE substr(mois_suivant,5,2) = substr(exercice_mois_comptable_1,5,2);
|
|
|
|
|
|
DROP TABLE IF EXISTS w_exercice;
|
|
|
CREATE TEMP TABLE w_exercice AS
|
|
|
SELECT exercice_comptable,
|
|
|
MIN(date_debut) AS date_debut_exercice,
|
|
|
MAX(date_fin) AS date_fin_exercice
|
|
|
FROM base.p_calendrier_mois
|
|
|
GROUP BY 1;
|
|
|
|
|
|
|
|
|
-- Extourne automatique mois suivant de toutes les écritures du journal
|
|
|
DROP TABLE IF EXISTS w_ECRIT_report;
|
|
|
CREATE TEMP TABLE w_ECRIT_report AS
|
|
|
SELECT w_ECRIT.*
|
|
|
FROM w_ECRIT
|
|
|
JOIN compta.t_journaux ON code_original = JNAL_CODEJ
|
|
|
WHERE JNAL_TYP = 'S' AND ECR_ANNUL = '' AND
|
|
|
report_automatique_mois_suivant = '1';
|
|
|
|
|
|
UPDATE w_ECRIT_report SET
|
|
|
ECR_CREDIT = ECR_DEBIT,
|
|
|
ECR_DEBIT = ECR_CREDIT,
|
|
|
mois_comptable = mois_suivant
|
|
|
FROM w_mois
|
|
|
WHERE w_mois.mois = mois_comptable;
|
|
|
|
|
|
INSERT INTO w_ECRIT
|
|
|
SELECT *
|
|
|
FROM w_ECRIT_report;
|
|
|
|
|
|
|
|
|
|
|
|
-- Ne pas tenir compte des ecritures de situation au permier jour et au dernier jour de l'exercice
|
|
|
DELETE FROM w_ECRIT
|
|
|
USING compta.t_journaux, w_exercice
|
|
|
WHERE code_original = JNAL_CODEJ AND
|
|
|
JNAL_TYP = 'S' AND ECR_ANNUL = '' AND
|
|
|
report_automatique_mois_suivant = '2' AND
|
|
|
date(ECR_DATE) = date_debut_exercice;
|
|
|
|
|
|
DELETE FROM w_ECRIT
|
|
|
USING compta.t_journaux, w_exercice
|
|
|
WHERE code_original = JNAL_CODEJ AND
|
|
|
JNAL_TYP = 'S' AND ECR_ANNUL = '' AND
|
|
|
report_automatique_mois_suivant = '2' AND
|
|
|
date(ECR_DATE) = date_fin_exercice;
|
|
|
|
|
|
|
|
|
-- Extourne automatique mois suivant en testant qu'au premier jour le solde soit à 0
|
|
|
DROP TABLE IF EXISTS w_ECRIT_situ;
|
|
|
CREATE TEMP TABLE w_ECRIT_situ AS
|
|
|
SELECT w_ECRIT.*,
|
|
|
to_char(date(ECR_DATE - interval '1 day' + interval '1 month'),'YYYYMM')::numeric AS mois_zero
|
|
|
FROM w_ECRIT
|
|
|
JOIN compta.t_journaux ON code_original = JNAL_CODEJ
|
|
|
WHERE JNAL_TYP = 'S' AND ECR_ANNUL = '' AND
|
|
|
report_automatique_mois_suivant IN ('2') ;
|
|
|
|
|
|
|
|
|
INSERT INTO w_ECRIT
|
|
|
(
|
|
|
ECR_STE,
|
|
|
ECR_AGE,
|
|
|
site_code,
|
|
|
ECR_JNAL,
|
|
|
ECR_PLAN,
|
|
|
ECR_CPTE,
|
|
|
ECR_CEMT,
|
|
|
ECR_SRC,
|
|
|
ECR_SANA,
|
|
|
compte_numero,
|
|
|
compte_numero_extra,
|
|
|
compte_numero_contre,
|
|
|
partenaire_code,
|
|
|
jnal_typ,
|
|
|
jnal_codej,
|
|
|
jnal_refbase,
|
|
|
mois_comptable,
|
|
|
|
|
|
ECR_DATE,
|
|
|
|
|
|
ECR_PIECE,
|
|
|
ECR_NUM,
|
|
|
ECR_FOLIO,
|
|
|
ECR_NLIG,
|
|
|
ECR_CHEQ,
|
|
|
ECR_ANNUL,
|
|
|
ECR_LIBEL,
|
|
|
|
|
|
ECR_DEBIT,
|
|
|
ECR_CREDIT
|
|
|
)
|
|
|
SELECT ECR_STE,
|
|
|
ECR_AGE,
|
|
|
site_code,
|
|
|
ECR_JNAL,
|
|
|
ECR_PLAN,
|
|
|
ECR_CPTE,
|
|
|
ECR_CEMT,
|
|
|
'C'::text AS ECR_SRC,
|
|
|
ECR_SANA,
|
|
|
compte_numero,
|
|
|
compte_numero_extra,
|
|
|
compte_numero_contre,
|
|
|
partenaire_code,
|
|
|
jnal_typ,
|
|
|
jnal_codej,
|
|
|
jnal_refbase,
|
|
|
mois_zero AS mois_comptable,
|
|
|
|
|
|
p_calendrier_mois.date_debut AS ECR_DATE,
|
|
|
|
|
|
'CTI'::text AS ECR_PIECE,
|
|
|
0::numeric AS ECR_NUM,
|
|
|
0::numeric AS ECR_FOLIO,
|
|
|
0::numeric AS ECR_NLIG,
|
|
|
''::text AS ECR_CHEQ,
|
|
|
''::text AS ECR_ANNUL,
|
|
|
'Extourne automatique CTI'::text AS ECR_LIBEL,
|
|
|
|
|
|
SUM(ECR_CREDIT) AS ECR_DEBIT,
|
|
|
SUM(ECR_DEBIT) AS ECR_CREDIT
|
|
|
|
|
|
FROM w_ECRIT_situ
|
|
|
JOIN base.p_calendrier_mois ON mois = mois_zero
|
|
|
GROUP BY 1,2,3,4,5,6,7,8,9,10,11,12,13,14,15,16,17,18
|
|
|
HAVING SUM(ECR_CREDIT) <> 0 OR SUM(ECR_DEBIT) <> 0
|
|
|
ORDER BY 1,2;
|
|
|
|
|
|
|
|
|
-- Comptabilité analytiques
|
|
|
INSERT INTO w_ECRIT
|
|
|
SELECT
|
|
|
ECRIT_COMPTA.*,
|
|
|
COALESCE(ECRIT_COMPTALIBEL.ECR_LIBEL,'') AS ECR_LIBEL,
|
|
|
ECRIT_COMPTA.ECR_STE||'-'||ECRIT_COMPTA.ECR_AGE AS site_code,
|
|
|
date_part('year',ECRIT_COMPTA.ECR_DATE) * 100 + date_part('month',ECRIT_COMPTA.ECR_DATE) AS mois_comptable,
|
|
|
ECRIT_COMPTA.ECR_CEMT AS compte_numero,
|
|
|
ECRIT_COMPTA.ECR_CEMT AS compte_numero_extra,
|
|
|
''::text AS partenaire_code,
|
|
|
'A'::text AS ECR_SRC,
|
|
|
ECR_CPTE AS ECR_SANA,
|
|
|
ECRIT_COMPTA.ECR_CREDIT AS ECR_CREDIT_ANA,
|
|
|
ECRIT_COMPTA.ECR_DEBIT AS ECR_DEBIT_ANA,
|
|
|
JNAL.TYP AS JNAL_TYP,
|
|
|
JNAL.CODEJ AS JNAL_CODEJ,
|
|
|
JNAL.REFBASE AS JNAL_REFBASE,
|
|
|
''::text AS compte_numero_contre
|
|
|
FROM prod_sigems.ECRIT_COMPTAANALYTIQUE ECRIT_COMPTA
|
|
|
JOIN w_STE ON ECRIT_COMPTA.ECR_STE || CASE WHEN '[SITES]' = '' THEN '' ELSE '-' || ECRIT_COMPTA.ECR_AGE END = SEL_STE
|
|
|
JOIN prod_sigems.JNAL ON ECRIT_COMPTA.ECR_JNAL = JNAL.CODEJ
|
|
|
LEFT JOIN prod_sigems.ECRIT_COMPTAANALYTIQUELIBEL ECRIT_COMPTALIBEL ON ECRIT_COMPTA.ECR_NUM = ECRIT_COMPTALIBEL.ECR_NUM
|
|
|
WHERE ECRIT_COMPTA.ECR_DATE >= '20100101' AND
|
|
|
ECRIT_COMPTA.ECR_ANNUL <> 'T' AND
|
|
|
ECRIT_COMPTA.ECR_ANNUL <> 'S' AND
|
|
|
ECRIT_COMPTA.ECR_PIECE <> 'CENTRALI' AND
|
|
|
ECRIT_COMPTA.ECR_PLAN IN ('A')
|
|
|
;
|
|
|
|
|
|
|
|
|
|
|
|
CREATE INDEX w_ECRIT_i1 ON w_ECRIT USING btree (ECR_NUM);
|
|
|
CREATE INDEX w_ECRIT_i2 ON w_ECRIT USING btree (mois_comptable);
|
|
|
CREATE INDEX w_ECRIT_i3 ON w_ECRIT USING btree (compte_numero);
|
|
|
CREATE INDEX w_ECRIT_i4 ON w_ECRIT USING btree (compte_numero_extra);
|
|
|
CREATE INDEX w_ECRIT_i5 ON w_ECRIT USING btree (partenaire_code);
|
|
|
CREATE INDEX w_ECRIT_i6 ON w_ECRIT USING btree (ECR_JNAL);
|
|
|
CREATE INDEX w_ECRIT_i7 ON w_ECRIT USING btree (site_code);
|
|
|
CREATE INDEX w_ECRIT_i8 ON w_ECRIT USING btree (ECR_SANA);
|
|
|
|
|
|
|
|
|
-- Attribution du code partenaire (tiers) sur les lignes d'écritures d'une même pièce comptable
|
|
|
-- Lignes d'écritures des partenaires
|
|
|
DROP TABLE IF EXISTS lignes_tiers
|
|
|
;
|
|
|
|
|
|
CREATE TEMP TABLE lignes_tiers AS
|
|
|
SELECT
|
|
|
ecr_piece,
|
|
|
w_ECRIT.ECR_PLAN || ECR_CPTE AS partenaire_code
|
|
|
FROM w_ECRIT
|
|
|
WHERE ecr_plan = 'F'
|
|
|
;
|
|
|
|
|
|
-- Mise à jour de la table de travail des écritures comptables
|
|
|
UPDATE w_ECRIT
|
|
|
SET partenaire_code = lignes_tiers.partenaire_code
|
|
|
FROM lignes_tiers
|
|
|
WHERE w_ECRIT.ecr_piece = lignes_tiers.ecr_piece
|
|
|
;
|
|
|
|
|
|
|
|
|
DROP TABLE IF EXISTS w_TECRIT;
|
|
|
CREATE TEMP TABLE w_TECRIT AS
|
|
|
SELECT
|
|
|
0::numeric AS exercice_comptable,
|
|
|
mois_comptable,
|
|
|
compte_numero_extra,
|
|
|
Count(*) AS COUNT,
|
|
|
round(SUM(CASE WHEN JNAL_TYP <> 'S' AND ECR_SRC <> 'A' THEN ECR_DEBIT ELSE 0 END),2) AS ECR_DEBIT,
|
|
|
round(SUM(CASE WHEN JNAL_TYP <> 'S' AND ECR_SRC <> 'A' THEN ECR_CREDIT ELSE 0 END),2) AS ECR_CREDIT,
|
|
|
round(SUM(CASE WHEN JNAL_TYP = 'S' OR ECR_SRC = 'A' THEN ECR_DEBIT ELSE 0 END),2) AS ECR_DEBIT_ajustement,
|
|
|
round(SUM(CASE WHEN JNAL_TYP = 'S' OR ECR_SRC = 'A' THEN ECR_CREDIT ELSE 0 END),2) AS ECR_CREDIT_ajustement
|
|
|
FROM w_ECRIT
|
|
|
GROUP BY 1,2,3
|
|
|
ORDER BY 1,2,3;
|
|
|
|
|
|
CREATE INDEX w_TECRIT_i1 ON w_ECRIT USING btree (mois_comptable);
|
|
|
CREATE INDEX w_TECRIT_i2 ON w_ECRIT USING btree (compte_numero_extra);
|
|
|
|
|
|
UPDATE w_TECRIT
|
|
|
SET exercice_comptable = p_calendrier_mois.exercice_comptable
|
|
|
FROM base.p_calendrier_mois
|
|
|
WHERE p_calendrier_mois.mois = w_TECRIT.mois_comptable;
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
DROP TABLE IF EXISTS w_mois_modifies;
|
|
|
CREATE TEMP TABLE w_mois_modifies AS
|
|
|
SELECT w_TECRIT.mois_comptable, w_TECRIT.exercice_comptable
|
|
|
FROM w_TECRIT
|
|
|
LEFT JOIN w_historique_ecritures_total ON
|
|
|
w_historique_ecritures_total.mois_comptable = w_TECRIT.mois_comptable AND
|
|
|
w_historique_ecritures_total.compte_numero_extra = w_TECRIT.compte_numero_extra
|
|
|
GROUP BY 1,2
|
|
|
HAVING MAX(CASE WHEN w_historique_ecritures_total.count IS DISTINCT FROM w_TECRIT.count OR
|
|
|
w_historique_ecritures_total.debit IS DISTINCT FROM w_TECRIT.ECR_DEBIT OR
|
|
|
w_historique_ecritures_total.credit IS DISTINCT FROM w_TECRIT.ECR_CREDIT OR
|
|
|
w_historique_ecritures_total.debit_ajustement IS DISTINCT FROM w_TECRIT.ECR_DEBIT_ajustement OR
|
|
|
w_historique_ecritures_total.credit_ajustement IS DISTINCT FROM w_TECRIT.ECR_CREDIT_ajustement
|
|
|
THEN 1 ELSE 0 END) = 1;
|
|
|
|
|
|
ALTER TABLE w_mois_modifies ADD CONSTRAINT w_mois_modifies_pk PRIMARY KEY(mois_comptable);
|
|
|
|
|
|
CTISELECT_PROPERTY_READ 'MOISMODIFIES', COALESCE(base.cti_group_concat(mois_comptable),'0')
|
|
|
FROM w_mois_modifies;
|
|
|
|
|
|
|
|
|
|
|
|
echo Mois modifiés : [MOISMODIFIES];
|
|
|
|
|
|
-- Morceau de code temporaire pouvant être enlever à partir de Juin 2024
|
|
|
-- L'insertion en base de données ne s'effectue uniquement sur la détection d'un changement de montant pour un mois donné
|
|
|
-- A la prochaine détection d'un changement :
|
|
|
-- Correction de la mauvaise attribution du code partenaire sur toutes les écritures antérieures et actuelles
|
|
|
UPDATE compta.p_historique_ecritures
|
|
|
SET partenaire_id = subview.partenaire_id
|
|
|
FROM (
|
|
|
SELECT
|
|
|
w_ECRIT.ecr_num,
|
|
|
t_partenaires.oid AS partenaire_id
|
|
|
FROM w_ECRIT
|
|
|
JOIN lignes_tiers ON lignes_tiers.ecr_piece = w_ECRIT.ecr_piece
|
|
|
JOIN compta.t_partenaires ON t_partenaires.code = lignes_tiers.partenaire_code
|
|
|
WHERE w_ECRIT.ecr_plan = 'G'
|
|
|
) AS subview
|
|
|
WHERE
|
|
|
p_historique_ecritures.cle_originale = subview.ecr_num
|
|
|
AND p_historique_ecritures.partenaire_id = 0
|
|
|
;
|
|
|
|
|
|
-- Les vues de l'application se base sur la table p_historique_ecritures_total se basant elle même sur p_historique_ecritures précédemment modifiée
|
|
|
UPDATE compta.p_historique_ecritures_total
|
|
|
SET partenaire_id = p_historique_ecritures.partenaire_id
|
|
|
FROM compta.p_historique_ecritures
|
|
|
WHERE
|
|
|
p_historique_ecritures_total.compte_id = p_historique_ecritures.compte_id
|
|
|
AND p_historique_ecritures_total.mois_comptable = p_historique_ecritures.mois_comptable
|
|
|
AND p_historique_ecritures_total.journal_id = p_historique_ecritures.journal_id
|
|
|
AND p_historique_ecritures_total.section_analytique_id = p_historique_ecritures.section_analytique_id
|
|
|
AND p_historique_ecritures_total.section_analytique_2_id = p_historique_ecritures.section_analytique_2_id
|
|
|
AND p_historique_ecritures_total.section_analytique_3_id = p_historique_ecritures.section_analytique_3_id
|
|
|
AND p_historique_ecritures_total.section_analytique_4_id = p_historique_ecritures.section_analytique_4_id
|
|
|
AND p_historique_ecritures_total.section_analytique_5_id = p_historique_ecritures.section_analytique_5_id
|
|
|
AND p_historique_ecritures_total.section_analytique_6_id = p_historique_ecritures.section_analytique_6_id
|
|
|
AND p_historique_ecritures_total.section_analytique_7_id = p_historique_ecritures.section_analytique_7_id
|
|
|
AND p_historique_ecritures_total.section_analytique_8_id = p_historique_ecritures.section_analytique_8_id
|
|
|
AND p_historique_ecritures_total.section_analytique_9_id = p_historique_ecritures.section_analytique_9_id
|
|
|
AND p_historique_ecritures_total.clinique_honoraire = p_historique_ecritures.clinique_honoraire
|
|
|
AND p_historique_ecritures_total.exercice_comptable = p_historique_ecritures.exercice_comptable
|
|
|
AND p_historique_ecritures_total.type_compta_id = p_historique_ecritures.type_compta_id
|
|
|
AND p_historique_ecritures_total.site_id = p_historique_ecritures.site_id
|
|
|
AND p_historique_ecritures_total.compte_extra_id = p_historique_ecritures.compte_extra_id
|
|
|
AND p_historique_ecritures_total.comptabilisee = p_historique_ecritures.comptabilisee
|
|
|
AND p_historique_ecritures_total.fin_exercice = p_historique_ecritures.fin_exercice
|
|
|
AND p_historique_ecritures_total.ajustement = p_historique_ecritures.ajustement
|
|
|
AND p_historique_ecritures_total.inter_site = p_historique_ecritures.inter_site
|
|
|
AND p_historique_ecritures_total.ecriture_consolidee = p_historique_ecritures.ecriture_consolidee
|
|
|
;
|
|
|
|
|
|
]]></sqlcmd>
|
|
|
</NODE>
|
|
|
|
|
|
|
|
|
|
|
|
</NODE>
|
|
|
|
|
|
<NODE name="ECRITURES" label="RECUPERATION ECRITURES">
|
|
|
<condition><![CDATA[
|
|
|
"[MOISMODIFIES]" != "0"
|
|
|
]]></condition>
|
|
|
|
|
|
<NODE label="Suppression avant regénération">
|
|
|
<sqlcmd><![CDATA[
|
|
|
|
|
|
SELECT base.cti_disable_index('compta', 'i_historique_ecritures_2');
|
|
|
SELECT base.cti_disable_index('compta', 'i_historique_ecritures_3');
|
|
|
SELECT base.cti_disable_index('compta', 'i_historique_ecritures_4');
|
|
|
SELECT base.cti_disable_index('compta', 'i_historique_ecritures_5');
|
|
|
SELECT base.cti_disable_index('compta', 'i_historique_ecritures_6');
|
|
|
SELECT base.cti_disable_index('compta', 'i_historique_ecritures_7');
|
|
|
SELECT base.cti_disable_index('compta', 'i_historique_ecritures_8');
|
|
|
SELECT base.cti_disable_index('compta', 'i_historique_ecritures_9');
|
|
|
SELECT base.cti_disable_index('compta', 'i_historique_ecritures_10');
|
|
|
SELECT base.cti_disable_index('compta', 'i_historique_ecritures_11');
|
|
|
SELECT base.cti_disable_index('compta', 'i_historique_ecritures_12');
|
|
|
SELECT base.cti_disable_index('compta', 'i_historique_ecritures_13');
|
|
|
|
|
|
|
|
|
DELETE FROM compta.p_historique_ecritures
|
|
|
USING w_mois_modifies
|
|
|
WHERE p_historique_ecritures.mois_comptable = w_mois_modifies.mois_comptable AND
|
|
|
is_budget IS DISTINCT FROM '1';
|
|
|
|
|
|
SELECT base.cti_disable_index('compta', 'i_historique_ecritures_1');
|
|
|
|
|
|
|
|
|
|
|
|
SELECT base.cti_disable_index('compta', 'i_historique_ecritures_total_2');
|
|
|
SELECT base.cti_disable_index('compta', 'i_historique_ecritures_total_3');
|
|
|
SELECT base.cti_disable_index('compta', 'i_historique_ecritures_total_4');
|
|
|
SELECT base.cti_disable_index('compta', 'i_historique_ecritures_total_5');
|
|
|
SELECT base.cti_disable_index('compta', 'i_historique_ecritures_total_6');
|
|
|
SELECT base.cti_disable_index('compta', 'i_historique_ecritures_total_7');
|
|
|
SELECT base.cti_disable_index('compta', 'i_historique_ecritures_total_8');
|
|
|
SELECT base.cti_disable_index('compta', 'i_historique_ecritures_total_9');
|
|
|
SELECT base.cti_disable_index('compta', 'i_historique_ecritures_total_10');
|
|
|
SELECT base.cti_disable_index('compta', 'i_historique_ecritures_total_11');
|
|
|
SELECT base.cti_disable_index('compta', 'i_historique_ecritures_total_12');
|
|
|
SELECT base.cti_disable_index('compta', 'i_historique_ecritures_total_13');
|
|
|
|
|
|
|
|
|
SELECT base.cti_disable_index('compta', 'i_historique_ecritures_total_1');
|
|
|
|
|
|
|
|
|
|
|
|
]]></sqlcmd>
|
|
|
</NODE>
|
|
|
|
|
|
<NODE label="Génération détail">
|
|
|
<sqlcmd><![CDATA[
|
|
|
|
|
|
INSERT INTO compta.p_historique_ecritures
|
|
|
(site_id,
|
|
|
type_compta_id,
|
|
|
compte_id,
|
|
|
date_ecriture,
|
|
|
exercice_comptable,
|
|
|
mois_comptable,
|
|
|
clinique_honoraire,
|
|
|
journal_id,
|
|
|
section_analytique_id,
|
|
|
partenaire_id,
|
|
|
compte_extra_id,
|
|
|
comptabilisee,
|
|
|
fin_exercice,
|
|
|
ajustement,
|
|
|
inter_site,
|
|
|
cle_originale,
|
|
|
identifiant_operation,
|
|
|
compte_contrepartie_id,
|
|
|
texte,
|
|
|
date_facture_fournisseur,
|
|
|
piece,
|
|
|
dossier,
|
|
|
date_echeance,
|
|
|
journal_paiement_id,
|
|
|
mode_paiement_id,
|
|
|
numero_cheque,
|
|
|
montant_credit,
|
|
|
montant_debit)
|
|
|
SELECT
|
|
|
t_sites.oid AS site_id,
|
|
|
t_comptes.type_compta_id,
|
|
|
t_comptes.compte_general_id AS compte_id,
|
|
|
date(ECR_DATE) AS date_ecriture,
|
|
|
w_mois_modifies.exercice_comptable,
|
|
|
w_mois_modifies.mois_comptable,
|
|
|
CASE WHEN JNAL_REFBASE IN ('H', 'M') THEN 'H' ELSE 'C' END AS clinique_honoraire,
|
|
|
t_journaux.oid AS journal_id,
|
|
|
COALESCE(t_sections_analytiques.oid, 0) AS section_analytique_id,
|
|
|
COALESCE(t_partenaires.oid,0) AS partenaire_id,
|
|
|
t_comptes.oid AS compte_extra_id,
|
|
|
'1'::text AS comptabilisee,
|
|
|
'0'::text AS fin_exercice,
|
|
|
CASE WHEN JNAL_TYP = 'S' OR ECR_SRC = 'A' THEN '2'::text ELSE '0'::text END AS ajustement,
|
|
|
'0'::text AS inter_site,
|
|
|
ECR_NUM::text AS cle_originale,
|
|
|
ECR_FOLIO||'.'||ECR_NLIG AS identifiant_operation,
|
|
|
COALESCE(t_comptes_contre.oid,0) AS compte_contrepartie_id,
|
|
|
substr(ECR_LIBEL,1,100) AS texte,
|
|
|
'20991231'::date AS date_facture_fournisseur,
|
|
|
ECR_PIECE AS piece,
|
|
|
''::text AS dossier,
|
|
|
date(ECR_ECHEA) AS date_echeance,
|
|
|
0::bigint AS journal_paiement_id,
|
|
|
0::bigint AS mode_paiement_id,
|
|
|
ECR_CHEQ AS numero_cheque,
|
|
|
ECR_CREDIT AS montant_credit,
|
|
|
ECR_DEBIT AS montant_debit
|
|
|
FROM w_ECRIT
|
|
|
JOIN w_mois_modifies ON w_mois_modifies.mois_comptable = w_ECRIT.mois_comptable
|
|
|
JOIN compta.t_sites ON site_code = t_sites.code_original
|
|
|
JOIN compta.t_journaux ON ECR_JNAL = t_journaux.code_original
|
|
|
JOIN compta.t_comptes ON compte_numero_extra = t_comptes.numero
|
|
|
LEFT JOIN compta.t_partenaires ON partenaire_code = t_partenaires.code_original
|
|
|
LEFT JOIN compta.t_sections_analytiques ON ECR_SANA = t_sections_analytiques.code_original
|
|
|
LEFT JOIN compta.t_comptes t_comptes_contre ON t_comptes_contre.oid = -1
|
|
|
ORDER BY ECR_NUM
|
|
|
;
|
|
|
|
|
|
|
|
|
SELECT base.cti_enable_index('compta', 'i_historique_ecritures_1');
|
|
|
SELECT base.cti_enable_index('compta', 'i_historique_ecritures_2');
|
|
|
SELECT base.cti_enable_index('compta', 'i_historique_ecritures_3');
|
|
|
SELECT base.cti_enable_index('compta', 'i_historique_ecritures_4');
|
|
|
SELECT base.cti_enable_index('compta', 'i_historique_ecritures_5');
|
|
|
SELECT base.cti_enable_index('compta', 'i_historique_ecritures_6');
|
|
|
SELECT base.cti_enable_index('compta', 'i_historique_ecritures_7');
|
|
|
SELECT base.cti_enable_index('compta', 'i_historique_ecritures_8');
|
|
|
SELECT base.cti_enable_index('compta', 'i_historique_ecritures_9');
|
|
|
SELECT base.cti_enable_index('compta', 'i_historique_ecritures_10');
|
|
|
SELECT base.cti_enable_index('compta', 'i_historique_ecritures_11');
|
|
|
SELECT base.cti_enable_index('compta', 'i_historique_ecritures_12');
|
|
|
SELECT base.cti_enable_index('compta', 'i_historique_ecritures_13');
|
|
|
|
|
|
|
|
|
|
|
|
]]></sqlcmd>
|
|
|
</NODE>
|
|
|
|
|
|
</NODE>
|
|
|
|
|
|
<NODE name="POST" label="TRAITEMENTS COMPLEMENTAIRES COMMUNS">
|
|
|
|
|
|
<condition><![CDATA[
|
|
|
"[MOISMODIFIES]" != "0"
|
|
|
]]></condition>
|
|
|
|
|
|
|
|
|
<NODE label="Compléments écritures">
|
|
|
|
|
|
<sqlcmd><![CDATA[
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
UPDATE compta.p_historique_ecritures
|
|
|
SET 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">
|
|
|
|
|
|
<condition><![CDATA[
|
|
|
"[MOISMODIFIES]" != "0"
|
|
|
]]></condition>
|
|
|
|
|
|
<NODE label="Récupération chiffrier">
|
|
|
<sqlcmd><![CDATA[
|
|
|
|
|
|
DROP TABLE IF EXISTS w_VALID;
|
|
|
CREATE TEMP TABLE w_VALID AS
|
|
|
SELECT
|
|
|
date_part('year',VAL_DATE2) * 100 + date_part('month',VAL_DATE2) AS mois_comptable,
|
|
|
t_sites.oid AS site_id,
|
|
|
CASE WHEN SAIS1 = 'H' THEN 'H' ELSE 'C' END AS clinique_honoraire,
|
|
|
t_journaux.oid AS journal_id,
|
|
|
SUM(VAL_CREDIT) AS montant_credit,
|
|
|
SUM(VAL_DEBIT) AS montant_debit
|
|
|
FROM prod_sigems.VALID
|
|
|
JOIN w_STE ON VAL_STE || CASE WHEN '[SITES]' = '' THEN '' ELSE '-' || VAL_AGE END = SEL_STE
|
|
|
JOIN prod_sigems.JNAL ON VAL_JNAL = CODEJ AND
|
|
|
TYP <> 'S'
|
|
|
JOIN compta.t_sites ON (VAL_STE || CASE WHEN '[SITES]' = '' THEN '' ELSE '-' || VAL_AGE END) = t_sites.code_original
|
|
|
JOIN compta.t_journaux ON VAL_JNAL = t_journaux.code_original
|
|
|
WHERE VAL_DATE1 >= '20100101' AND
|
|
|
(VAL_CREDIT <> 0 OR VAL_DEBIT <> 0)
|
|
|
GROUP BY 1,2,3,4
|
|
|
ORDER BY 1,2,3,4;
|
|
|
|
|
|
DROP TABLE IF EXISTS w_VALID_periode;
|
|
|
CREATE TEMP TABLE w_VALID_periode AS
|
|
|
SELECT MIN(mois_comptable) AS mois_comptable_debut,
|
|
|
MAX(mois_comptable) AS mois_comptable_fin
|
|
|
FROM w_VALID;
|
|
|
|
|
|
CREATE INDEX w_VALID_i1 ON w_VALID USING btree (mois_comptable);
|
|
|
|
|
|
INSERT INTO w_VALID
|
|
|
SELECT
|
|
|
p_historique_ecritures_total.mois_comptable,
|
|
|
p_historique_ecritures_total.site_id,
|
|
|
p_historique_ecritures_total.clinique_honoraire,
|
|
|
p_historique_ecritures_total.journal_id,
|
|
|
SUM(p_historique_ecritures_total.montant_debit),
|
|
|
SUM(p_historique_ecritures_total.montant_credit)
|
|
|
FROM compta.p_historique_ecritures_total
|
|
|
JOIN w_VALID_periode ON mois_comptable BETWEEN mois_comptable_debut AND mois_comptable_fin
|
|
|
LEFT JOIN w_VALID ON
|
|
|
(
|
|
|
p_historique_ecritures_total.mois_comptable = w_VALID.mois_comptable AND
|
|
|
p_historique_ecritures_total.site_id = w_VALID.site_id AND
|
|
|
p_historique_ecritures_total.clinique_honoraire = w_VALID.clinique_honoraire AND
|
|
|
p_historique_ecritures_total.journal_id = w_VALID.journal_id
|
|
|
)
|
|
|
WHERE ajustement ='0' AND
|
|
|
is_budget IS DISTINCT FROM '1'
|
|
|
GROUP by 1,2,3,4
|
|
|
HAVING MAX(w_VALID.montant_debit) IS NULL
|
|
|
ORDER BY 1,2,3,4;
|
|
|
|
|
|
TRUNCATE compta.p_chiffrier_comptable;
|
|
|
|
|
|
INSERT INTO compta.p_chiffrier_comptable
|
|
|
(
|
|
|
mois_comptable,
|
|
|
site_id,
|
|
|
clinique_honoraire,
|
|
|
montant_debit,
|
|
|
montant_credit
|
|
|
)
|
|
|
SELECT
|
|
|
mois_comptable,
|
|
|
site_id,
|
|
|
clinique_honoraire,
|
|
|
SUM(montant_debit),
|
|
|
SUM(montant_credit)
|
|
|
FROM w_VALID
|
|
|
GROUP BY 1,2,3
|
|
|
HAVING SUM(montant_debit) <> 0 OR
|
|
|
SUM(montant_credit) <> 0;
|
|
|
|
|
|
]]></sqlcmd>
|
|
|
</NODE>
|
|
|
|
|
|
|
|
|
</NODE>
|
|
|
|
|
|
<NODE name="PARAM" label="RECUPERATION DES PARAMETRES">
|
|
|
|
|
|
<NODE label="Paramètres">
|
|
|
<sqlcmd><![CDATA[
|
|
|
|
|
|
-- Periode comptable
|
|
|
|
|
|
|
|
|
-- Site
|
|
|
DROP TABLE IF EXISTS w_STE;
|
|
|
CREATE TEMP TABLE w_STE AS
|
|
|
SELECT VAL_STE || CASE WHEN '[SITES]' = '' THEN '' ELSE '-' || VAL_AGE END AS SEL_STE
|
|
|
FROM prod_sigems.VALID
|
|
|
WHERE (VAL_STE::text = ANY (string_to_array('[ETAB]'::text,',')) OR
|
|
|
'[ETAB]' = '')
|
|
|
AND (VAL_AGE::text = ANY (string_to_array('[SITES]'::text,',')) OR
|
|
|
'[SITES]' = '')
|
|
|
GROUP BY 1
|
|
|
;
|
|
|
|
|
|
|
|
|
INSERT INTO compta.t_sites(code_original, code, texte, clinique_honoraire)
|
|
|
SELECT site_code, site_code, site_texte, 'C'
|
|
|
FROM
|
|
|
(SELECT ECR_STE || CASE WHEN '[SITES]' = '' THEN '' ELSE '-' || ECR_AGE END AS site_code,
|
|
|
ECR_STE || CASE WHEN '[SITES]' = '' THEN '' ELSE ' ' || ECR_AGE END AS site_texte
|
|
|
FROM prod_sigems.ECRIT_COMPTA
|
|
|
JOIN w_STE ON ECR_STE || CASE WHEN '[SITES]' = '' THEN '' ELSE '-' || ECR_AGE END = SEL_STE
|
|
|
GROUP BY 1,2) subview
|
|
|
WHERE site_code NOT IN (SELECT code_original FROM compta.t_sites WHERE code_original IS NOT NULL) ;
|
|
|
|
|
|
-- Types de compta
|
|
|
INSERT INTO compta.t_types_compta(code, code_original, texte, specialite)
|
|
|
SELECT code, code_original, texte, specialite
|
|
|
FROM
|
|
|
(
|
|
|
SELECT 'GES' AS code, 'GES' AS code_original, 'Gestion' AS texte, 'GES' AS specialite
|
|
|
UNION
|
|
|
SELECT 'BIL', 'BIL', 'Bilan', 'BIL'
|
|
|
UNION
|
|
|
SELECT 'RES' AS code, 'RES' AS code_original, 'Résuultat' AS texte, 'RES' AS specialite
|
|
|
UNION
|
|
|
SELECT 'CLI', 'CLI', 'Clients', 'CLI'
|
|
|
UNION
|
|
|
SELECT 'FOU', 'FOU', 'Fournisseurs', 'FOU'
|
|
|
UNION
|
|
|
SELECT 'MED', 'MED', 'Médecins', 'FOU'
|
|
|
UNION
|
|
|
SELECT 'DIV', 'DIV', 'Divers', 'FOU'
|
|
|
) subview
|
|
|
WHERE code_original NOT IN (SELECT code_original FROM compta.t_types_compta WHERE code_original IS NOT NULL);
|
|
|
|
|
|
|
|
|
INSERT INTO compta.t_sections_analytiques(oid, code, code_original, texte)
|
|
|
SELECT 0, '0000', '', 'Non renseignée'
|
|
|
WHERE 0 NOT IN (SELECT oid FROM compta.t_sections_analytiques);
|
|
|
|
|
|
INSERT INTO compta.t_sections_analytiques(code, code_original, texte)
|
|
|
SELECT
|
|
|
NUM,
|
|
|
NUM,
|
|
|
MAX(COMPTE.INT1||' '||COMPTE.INT2) AS texte
|
|
|
FROM prod_sigems.COMPTE
|
|
|
JOIN prod_sigems.ECRIT_COMPTAANA ON COMPTE.STE = ECR_STE AND
|
|
|
COMPTE.NUM = ECR_CPTE
|
|
|
WHERE TYP = 'A' AND
|
|
|
NUM NOT IN (SELECT code_original FROM compta.t_sections_analytiques)
|
|
|
GROUP BY 1,2;
|
|
|
|
|
|
INSERT INTO compta.t_sections_analytiques(code, code_original, texte)
|
|
|
SELECT
|
|
|
NUM,
|
|
|
NUM,
|
|
|
MAX(COMPTE.INT1||' '||COMPTE.INT2) AS texte
|
|
|
FROM prod_sigems.COMPTE
|
|
|
JOIN prod_sigems.ECRIT_COMPTAANALYTIQUE ON COMPTE.STE = ECR_STE AND
|
|
|
COMPTE.NUM = ECR_CPTE
|
|
|
WHERE TYP = 'A' AND
|
|
|
NUM NOT IN (SELECT code_original FROM compta.t_sections_analytiques)
|
|
|
GROUP BY 1,2;
|
|
|
|
|
|
|
|
|
-- Journaux
|
|
|
|
|
|
INSERT INTO compta.t_journaux(code_original, code, texte, a_nouveaux, clinique_honoraire)
|
|
|
SELECT CODEJ, CODEJ, LIBEL, '0', CASE WHEN REFBASE = 'H' THEN 'H' ELSE 'C' END
|
|
|
FROM prod_sigems.JNAL
|
|
|
WHERE CODEJ NOT IN (SELECT code_original FROM compta.t_journaux WHERE code_original IS NOT NULL) AND
|
|
|
CODEJ IN (SELECT ECR_JNAL FROM prod_sigems.ECRIT_COMPTA)
|
|
|
ORDER BY 1;
|
|
|
|
|
|
|
|
|
INSERT INTO compta.t_journaux(code_original, code, texte, a_nouveaux, clinique_honoraire)
|
|
|
SELECT CODEJ, CODEJ, LIBEL, '0', CASE WHEN REFBASE = 'H' THEN 'H' ELSE 'C' END
|
|
|
FROM prod_sigems.JNAL
|
|
|
WHERE CODEJ NOT IN (SELECT code_original FROM compta.t_journaux WHERE code_original IS NOT NULL) AND
|
|
|
CODEJ IN (SELECT ECR_JNAL FROM prod_sigems.ECRIT_COMPTAANALYTIQUE)
|
|
|
ORDER BY 1;
|
|
|
|
|
|
-- Classes de comptes
|
|
|
|
|
|
|
|
|
-- Comptes
|
|
|
DROP TABLE IF EXISTS w_COMPTE;
|
|
|
CREATE TEMP TABLE w_COMPTE AS
|
|
|
SELECT
|
|
|
ECR_STE,
|
|
|
ECR_PLAN,
|
|
|
ECR_CPTE,
|
|
|
CASE WHEN ECR_CEMT = '' THEN '' ELSE ECR_PLAN || ECR_CPTE END AS ECR_PART,
|
|
|
CASE WHEN ECR_CEMT = '' THEN ECR_CPTE ELSE ECR_CEMT END AS ECR_CEMT,
|
|
|
CASE WHEN ECR_CEMT = '' AND ECR_CEMT <> ECR_CPTE THEN ECR_CPTE ELSE ECR_CEMT END AS numero,
|
|
|
CASE WHEN ECR_CEMT = '' AND ECR_CEMT <> ECR_CPTE THEN ECR_CPTE ELSE ECR_CEMT || '-' || ECR_CPTE END AS numero_extra,
|
|
|
0::bigint AS type_compta_id,
|
|
|
0::bigint AS type_compta_extra_id
|
|
|
FROM prod_sigems.ECRIT_COMPTA
|
|
|
GROUP BY 1,2,3,4,5,6,7;
|
|
|
|
|
|
UPDATE w_COMPTE
|
|
|
SET type_compta_id = t_types_compta.oid
|
|
|
FROM compta.t_types_compta
|
|
|
WHERE (numero LIKE '6%' OR numero LIKE '7%' ) AND
|
|
|
t_types_compta.code = 'GES';
|
|
|
|
|
|
UPDATE w_COMPTE
|
|
|
SET type_compta_id = t_types_compta.oid
|
|
|
FROM compta.t_types_compta
|
|
|
WHERE (numero LIKE '8%' ) AND
|
|
|
t_types_compta.code = 'RES';
|
|
|
|
|
|
UPDATE w_COMPTE
|
|
|
SET type_compta_id = t_types_compta.oid
|
|
|
FROM compta.t_types_compta
|
|
|
WHERE (numero NOT LIKE '6%' AND numero NOT LIKE '7%' AND numero NOT LIKE '8%') AND
|
|
|
t_types_compta.code = 'BIL';
|
|
|
|
|
|
UPDATE w_COMPTE
|
|
|
SET type_compta_extra_id = t_types_compta.oid
|
|
|
FROM compta.t_types_compta
|
|
|
WHERE (numero LIKE '6%' OR numero LIKE '7%') AND
|
|
|
(ECR_PLAN = 'G' OR ECR_PLAN = 'H') AND
|
|
|
t_types_compta.code = 'GES';
|
|
|
|
|
|
UPDATE w_COMPTE
|
|
|
SET type_compta_extra_id = t_types_compta.oid
|
|
|
FROM compta.t_types_compta
|
|
|
WHERE (numero LIKE '8%') AND
|
|
|
(ECR_PLAN = 'G' OR ECR_PLAN = 'H') AND
|
|
|
t_types_compta.code = 'RES';
|
|
|
|
|
|
UPDATE w_COMPTE
|
|
|
SET type_compta_extra_id = t_types_compta.oid
|
|
|
FROM compta.t_types_compta
|
|
|
WHERE (numero NOT LIKE '6%' AND numero NOT LIKE '7%' AND numero NOT LIKE '8%') AND
|
|
|
(ECR_PLAN = 'G' OR ECR_PLAN = 'H') AND
|
|
|
t_types_compta.code = 'BIL';
|
|
|
|
|
|
UPDATE w_COMPTE
|
|
|
SET type_compta_extra_id = t_types_compta.oid
|
|
|
FROM compta.t_types_compta
|
|
|
WHERE ECR_PLAN = 'F' AND
|
|
|
t_types_compta.code = 'FOU';
|
|
|
|
|
|
UPDATE w_COMPTE
|
|
|
SET type_compta_extra_id = t_types_compta.oid
|
|
|
FROM compta.t_types_compta
|
|
|
WHERE ECR_PLAN = 'C' AND
|
|
|
t_types_compta.code = 'CLI';
|
|
|
|
|
|
UPDATE w_COMPTE
|
|
|
SET type_compta_extra_id = t_types_compta.oid
|
|
|
FROM compta.t_types_compta
|
|
|
WHERE ECR_PLAN = 'M' AND
|
|
|
t_types_compta.code = 'MED';
|
|
|
|
|
|
UPDATE w_COMPTE
|
|
|
SET type_compta_extra_id = t_types_compta.oid
|
|
|
FROM compta.t_types_compta
|
|
|
WHERE ECR_PLAN NOT IN ('G', 'H') AND
|
|
|
type_compta_extra_id = 0 AND
|
|
|
t_types_compta.code = 'DIV';
|
|
|
|
|
|
|
|
|
-- Comptes généraux
|
|
|
UPDATE compta.t_comptes SET
|
|
|
type_compta_id = subview.type_compta_id,
|
|
|
texte = subview.texte
|
|
|
FROM
|
|
|
(
|
|
|
SELECT
|
|
|
type_compta_id,
|
|
|
numero,
|
|
|
MAX(COMPTE.INT1||' '||COMPTE.INT2) AS texte
|
|
|
FROM w_COMPTE
|
|
|
JOIN prod_sigems.COMPTE ON COMPTE.STE = ECR_STE AND
|
|
|
COMPTE.NUM = ECR_CEMT
|
|
|
GROUP BY 1,2
|
|
|
) subview
|
|
|
WHERE t_comptes.numero = subview.numero AND
|
|
|
(
|
|
|
t_comptes.type_compta_id IS DISTINCT FROM subview.type_compta_id OR
|
|
|
t_comptes.texte IS DISTINCT FROM subview.texte
|
|
|
);
|
|
|
|
|
|
|
|
|
INSERT INTO compta.t_comptes(
|
|
|
type_compta_id, numero, texte, compte_general_id, clinique_honoraire,
|
|
|
banque, collectif, type_compta_extra_id, numero_extra, partenaire_id)
|
|
|
SELECT
|
|
|
type_compta_id,
|
|
|
numero,
|
|
|
MAX(COMPTE.INT1||' '||COMPTE.INT2) AS texte,
|
|
|
0 AS compte_general_id,
|
|
|
MIN(CASE WHEN ECR_PLAN IN ('H','M') THEN 'H' ELSE 'C' END) AS clinique_honoraire,
|
|
|
MAX(CASE WHEN numero LIKE '512%' THEN '1' ELSE '0' END) AS banque,
|
|
|
'0' AS collectif,
|
|
|
0 AS type_compta_extra_id,
|
|
|
'' AS numero_extra,
|
|
|
0::bigint AS partenaire_id
|
|
|
FROM w_COMPTE
|
|
|
LEFT JOIN prod_sigems.COMPTE ON COMPTE.STE = ECR_STE AND
|
|
|
COMPTE.NUM = ECR_CEMT
|
|
|
WHERE numero NOT IN (SELECT numero FROM compta.t_comptes WHERE numero IS NOT NULL) AND
|
|
|
w_COMPTE.numero <> ''
|
|
|
GROUP BY 1,2
|
|
|
ORDER BY 2;
|
|
|
|
|
|
-- Partenaires
|
|
|
INSERT INTO compta.t_partenaires(code_original, code, texte, texte_court)
|
|
|
SELECT ECR_PART, ECR_PART, MAX(COALESCE(COMPTE.INT1||' '||COMPTE.INT2,ECR_CPTE)), MAX(COALESCE(COMPTE.INT1||' '||COMPTE.INT2,ECR_CPTE))
|
|
|
FROM w_COMPTE
|
|
|
LEFT JOIN prod_sigems.COMPTE ON COMPTE.STE = ECR_STE AND
|
|
|
COMPTE.TYP = ECR_PLAN AND
|
|
|
COMPTE.NUM = ECR_CPTE
|
|
|
WHERE ECR_PART <> '' AND
|
|
|
ECR_PART NOT IN (SELECT code_original FROM compta.t_partenaires WHERE code_original IS NOT NULL)
|
|
|
GROUP BY 1,2;
|
|
|
|
|
|
UPDATE compta.t_partenaires SET
|
|
|
texte = COALESCE(COMPTE.INT1||' '||COMPTE.INT2,ECR_CPTE),
|
|
|
texte_court = COALESCE(COMPTE.INT1||' '||COMPTE.INT2,ECR_CPTE)
|
|
|
FROM w_COMPTE
|
|
|
LEFT JOIN prod_sigems.COMPTE ON COMPTE.STE = ECR_STE AND
|
|
|
COMPTE.TYP = ECR_PLAN AND
|
|
|
COMPTE.NUM = ECR_CPTE
|
|
|
WHERE ECR_PART = code_original AND
|
|
|
(
|
|
|
t_partenaires.texte IS DISTINCT FROM COALESCE(COMPTE.INT1||' '||COMPTE.INT2,ECR_CPTE) OR
|
|
|
t_partenaires.texte_court IS DISTINCT FROM COALESCE(COMPTE.INT1||' '||COMPTE.INT2,ECR_CPTE)
|
|
|
);
|
|
|
|
|
|
|
|
|
-- Comptes auxiliaires
|
|
|
UPDATE compta.t_comptes SET
|
|
|
type_compta_id = subview.type_compta_extra_id,
|
|
|
texte = subview.texte_extra,
|
|
|
partenaire_id = subview.partenaire_id
|
|
|
FROM
|
|
|
(
|
|
|
SELECT
|
|
|
type_compta_extra_id,
|
|
|
numero_extra,
|
|
|
MAX(COALESCE(t_partenaires.oid,0)) AS partenaire_id,
|
|
|
MAX(COALESCE(COMPTE.INT1||' '||COMPTE.INT2,ECR_CEMT)) AS texte_extra
|
|
|
FROM w_COMPTE
|
|
|
LEFT JOIN compta.t_partenaires ON ECR_PART = t_partenaires.code_original
|
|
|
LEFT JOIN prod_sigems.COMPTE ON COMPTE.STE = ECR_STE AND
|
|
|
COMPTE.TYP = ECR_PLAN AND
|
|
|
COMPTE.NUM = ECR_CPTE
|
|
|
WHERE w_COMPTE.numero <> ''
|
|
|
GROUP BY 1,2
|
|
|
) subview
|
|
|
WHERE t_comptes.numero = subview.numero_extra AND
|
|
|
(
|
|
|
t_comptes.type_compta_id IS DISTINCT FROM subview.type_compta_extra_id OR
|
|
|
t_comptes.texte IS DISTINCT FROM subview.texte_extra OR
|
|
|
t_comptes.partenaire_id IS DISTINCT FROM subview.partenaire_id
|
|
|
);
|
|
|
|
|
|
|
|
|
INSERT INTO compta.t_comptes(
|
|
|
type_compta_id, numero, texte, compte_general_id, clinique_honoraire,
|
|
|
banque, collectif, type_compta_extra_id, numero_extra, partenaire_id)
|
|
|
SELECT
|
|
|
w_COMPTE.type_compta_extra_id,
|
|
|
w_COMPTE.numero_extra,
|
|
|
MAX(COALESCE(COMPTE.INT1||' '||COMPTE.INT2,ECR_CEMT)) AS texte,
|
|
|
MAX(t_comptes.oid) AS compte_general_id,
|
|
|
MIN(CASE WHEN ECR_PLAN IN ('H','M') THEN 'H' ELSE 'C' END) AS clinique_honoraire,
|
|
|
MAX(CASE WHEN w_COMPTE.numero LIKE '512%' THEN '1' ELSE '0' END) AS banque,
|
|
|
'0' AS collectif,
|
|
|
0 AS type_compta_extra_id,
|
|
|
'' AS numero_extra,
|
|
|
MAX(COALESCE(t_partenaires.oid,0)) AS partenaire_id
|
|
|
FROM w_COMPTE
|
|
|
LEFT JOIN compta.t_partenaires ON ECR_PART = t_partenaires.code_original
|
|
|
LEFT JOIN prod_sigems.COMPTE ON COMPTE.STE = ECR_STE AND
|
|
|
COMPTE.TYP = ECR_PLAN AND
|
|
|
COMPTE.NUM = ECR_CPTE
|
|
|
JOIN compta.t_comptes ON t_comptes.numero = w_COMPTE.numero
|
|
|
WHERE w_COMPTE.numero_extra NOT IN (SELECT numero FROM compta.t_comptes WHERE numero IS NOT NULL) AND
|
|
|
w_COMPTE.numero <> ''
|
|
|
GROUP BY 1,2
|
|
|
ORDER BY 2;
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
UPDATE compta.t_comptes SET
|
|
|
compte_general_id = oid
|
|
|
WHERE compte_general_id = 0 OR compte_general_id IS NULL;
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
]]></sqlcmd>
|
|
|
</NODE>
|
|
|
|
|
|
</NODE>
|
|
|
|
|
|
</ROOT>
|