|
|
<?xml version="1.0" encoding="ISO-8859-1"?>
|
|
|
<ROOT>
|
|
|
|
|
|
|
|
|
<NODE name="INIT" label="INITIALISATIONS">
|
|
|
|
|
|
<NODE label="Détection Mois modifiés">
|
|
|
<sqlcmd><![CDATA[
|
|
|
|
|
|
-- 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 numero,
|
|
|
SUM(montant_debit) as debit,
|
|
|
SUM(montant_credit) as credit,
|
|
|
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 = '0' AND
|
|
|
is_budget IS DISTINCT FROM '1'
|
|
|
GROUP BY 1,2
|
|
|
ORDER BY 1,2;
|
|
|
|
|
|
-- Ecritures prestataire
|
|
|
DROP TABLE IF EXISTS w_TECRITURE;
|
|
|
CREATE TEMP TABLE w_TECRITURE AS
|
|
|
SELECT
|
|
|
date_part('year',DATEDEBUT) * 100 + date_part('month',DATEDEBUT) AS mois_comptable,
|
|
|
COALESCE(w_TCOMPTEAUXILIAIRE.CODECOMPTEAUXILIAIRE,TCOMPTEGENERAL.CODECOMPTE) AS CODECOMPTE,
|
|
|
date_part('year',DATEDEBUT) AS exercice_comptable,
|
|
|
date(MIN(DATEDEBUT)) AS DATEDEBUT,
|
|
|
date(MAX(DATEFIN)) AS DATEFIN,
|
|
|
Count(*) AS COUNT,
|
|
|
round(SUM(DEBIT),2) AS DEBIT,
|
|
|
round(SUM(CREDIT),2) AS CREDIT
|
|
|
FROM prod_sage100compta.TECRITURE
|
|
|
JOIN prod_sage100compta.TPIECE ON OIDPIECE = TPIECE.OID
|
|
|
JOIN prod_sage100compta.TPERIODE ON OIDPERIODE = TPERIODE.OID
|
|
|
JOIN prod_sage100compta.TCOMPTEGENERAL ON OIDCOMPTEGENERAL = TCOMPTEGENERAL.OID
|
|
|
LEFT JOIN w_TCOMPTEAUXILIAIRE ON TECRITURE.OIDCOMPTEGENERAL = w_TCOMPTEAUXILIAIRE.OIDCOMPTEGENERAL AND
|
|
|
TECRITURE.OIDROLETIERS = w_TCOMPTEAUXILIAIRE.OIDROLETIERS
|
|
|
WHERE typeecriture <> 0
|
|
|
GROUP BY 1,2,3
|
|
|
ORDER BY 1,2,3;
|
|
|
|
|
|
|
|
|
DROP TABLE IF EXISTS w_mois_modifies;
|
|
|
CREATE TEMP TABLE w_mois_modifies AS
|
|
|
SELECT w_TECRITURE.exercice_comptable,
|
|
|
w_TECRITURE.mois_comptable,
|
|
|
MIN(DATEDEBUT) AS DATEDEBUT,
|
|
|
MAX(DATEFIN) AS DATEFIN
|
|
|
FROM w_TECRITURE
|
|
|
LEFT JOIN w_historique_ecritures_total ON
|
|
|
w_historique_ecritures_total.mois_comptable = w_TECRITURE.mois_comptable AND
|
|
|
w_historique_ecritures_total.numero = w_TECRITURE.CODECOMPTE
|
|
|
GROUP BY 1,2
|
|
|
HAVING MAX(CASE WHEN w_historique_ecritures_total.count IS DISTINCT FROM w_TECRITURE.count OR
|
|
|
w_historique_ecritures_total.debit IS DISTINCT FROM w_TECRITURE.debit OR
|
|
|
w_historique_ecritures_total.credit IS DISTINCT FROM w_TECRITURE.credit
|
|
|
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];
|
|
|
|
|
|
]]></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(TPIECE.PDATE) AS date_ecriture,
|
|
|
w_mois_modifies.exercice_comptable,
|
|
|
w_mois_modifies.mois_comptable,
|
|
|
t_sites.clinique_honoraire,
|
|
|
t_journaux.oid AS journal_id,
|
|
|
COALESCE(t_sections_analytiques.oid,0) AS section_analytique_id,
|
|
|
COALESCE(w_TCOMPTEAUXILIAIRE.partenaire_id,0) AS partenaire_id,
|
|
|
COALESCE(w_TCOMPTEAUXILIAIRE.compte_auxiliaire_id,t_comptes.oid) AS compte_extra_id,
|
|
|
'1'::text AS comptabilisee,
|
|
|
'0'::text AS fin_exercice,
|
|
|
CASE WHEN TYPEECRITURE = 0 THEN '2'::text ELSE '0'::text END AS ajustement,
|
|
|
'0'::text AS inter_site,
|
|
|
substr(TECRITURE.OID,17) AS cle_originale,
|
|
|
substr(TPIECE.OID,17) AS identifiant_operation,
|
|
|
COALESCE(t_comptes_contre.oid,0) AS compte_contrepartie_id,
|
|
|
substr(TECRITURE.CAPTION,1,100) AS texte,
|
|
|
'20991231'::date AS date_facture_fournisseur,
|
|
|
substr(TPIECE.NUMERO,1,255) AS piece,
|
|
|
trim(NUMEROFACTUREGESCOM) AS dossier,
|
|
|
'20991231'::date AS date_echeance,
|
|
|
0::bigint AS journal_paiement_id,
|
|
|
0::bigint AS mode_paiement_id,
|
|
|
''::text AS numero_cheque,
|
|
|
CREDIT AS montant_credit,
|
|
|
DEBIT AS montant_debit
|
|
|
FROM prod_sage100compta.TECRITURE
|
|
|
JOIN prod_sage100compta.TPIECE ON OIDPIECE = TPIECE.OID
|
|
|
JOIN prod_sage100compta.TPERIODE ON OIDPERIODE = TPERIODE.OID
|
|
|
JOIN w_mois_modifies ON
|
|
|
date(TPERIODE.DATEDEBUT) BETWEEN w_mois_modifies.DATEDEBUT AND w_mois_modifies.DATEDEBUT
|
|
|
JOIN prod_sage100compta.TCOMPTEGENERAL ON TECRITURE.OIDCOMPTEGENERAL = TCOMPTEGENERAL.OID
|
|
|
JOIN compta.t_sites ON OIDETABLISSEMENT = t_sites.code_original
|
|
|
JOIN compta.t_journaux ON OIDJOURNAL = t_journaux.code_original
|
|
|
JOIN compta.t_comptes ON CODECOMPTE = t_comptes.numero
|
|
|
LEFT JOIN w_TCOMPTEAUXILIAIRE ON TECRITURE.OIDCOMPTEGENERAL = w_TCOMPTEAUXILIAIRE.OIDCOMPTEGENERAL AND
|
|
|
TECRITURE.OIDROLETIERS = w_TCOMPTEAUXILIAIRE.OIDROLETIERS
|
|
|
LEFT JOIN prod_sage100compta.TPOINTANALYTIQUE ON OIDSECTIONANALYTIQUELIGNE = TPOINTANALYTIQUE.OID
|
|
|
LEFT JOIN compta.t_sections_analytiques ON TPOINTANALYTIQUE.OIDSECTIONANALYTIQUE = t_sections_analytiques.code_original
|
|
|
LEFT JOIN compta.t_comptes t_comptes_contre ON t_comptes_contre.oid = -1
|
|
|
ORDER BY TECRITURE.OID
|
|
|
;
|
|
|
|
|
|
-- Ecritures de cloture à contrepasser en ajustement pour résultat
|
|
|
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(TPIECE.PDATE) AS date_ecriture,
|
|
|
w_mois_modifies.exercice_comptable,
|
|
|
w_mois_modifies.mois_comptable,
|
|
|
t_sites.clinique_honoraire,
|
|
|
t_journaux.oid AS journal_id,
|
|
|
COALESCE(t_sections_analytiques.oid,0) AS section_analytique_id,
|
|
|
COALESCE(w_TCOMPTEAUXILIAIRE.partenaire_id,0) AS partenaire_id,
|
|
|
COALESCE(w_TCOMPTEAUXILIAIRE.compte_auxiliaire_id,t_comptes.oid) AS compte_extra_id,
|
|
|
'1'::text AS comptabilisee,
|
|
|
'0'::text AS fin_exercice,
|
|
|
'2'::text AS ajustement,
|
|
|
'0'::text AS inter_site,
|
|
|
substr(TECRITURE.OID,17) AS cle_originale,
|
|
|
substr(TPIECE.OID,17) AS identifiant_operation,
|
|
|
COALESCE(t_comptes_contre.oid,0) AS compte_contrepartie_id,
|
|
|
substr(TECRITURE.CAPTION,1,100) AS texte,
|
|
|
'20991231'::date AS date_facture_fournisseur,
|
|
|
substr(TPIECE.NUMERO,1,255) AS piece,
|
|
|
trim(NUMEROFACTUREGESCOM) AS dossier,
|
|
|
'20991231'::date AS date_echeance,
|
|
|
0::bigint AS journal_paiement_id,
|
|
|
0::bigint AS mode_paiement_id,
|
|
|
''::text AS numero_cheque,
|
|
|
0-CREDIT AS montant_credit,
|
|
|
0-DEBIT AS montant_debit
|
|
|
FROM prod_sage100compta.TECRITURE
|
|
|
JOIN prod_sage100compta.TPIECE ON OIDPIECE = TPIECE.OID
|
|
|
JOIN prod_sage100compta.TPERIODE ON OIDPERIODE = TPERIODE.OID
|
|
|
JOIN w_mois_modifies ON
|
|
|
date(TPERIODE.DATEDEBUT) BETWEEN w_mois_modifies.DATEDEBUT AND w_mois_modifies.DATEDEBUT
|
|
|
JOIN prod_sage100compta.TCOMPTEGENERAL ON TECRITURE.OIDCOMPTEGENERAL = TCOMPTEGENERAL.OID
|
|
|
JOIN compta.t_sites ON OIDETABLISSEMENT = t_sites.code_original
|
|
|
JOIN compta.t_journaux ON OIDJOURNAL = t_journaux.code_original
|
|
|
JOIN compta.t_comptes ON CODECOMPTE = t_comptes.numero
|
|
|
LEFT JOIN w_TCOMPTEAUXILIAIRE ON TECRITURE.OIDCOMPTEGENERAL = w_TCOMPTEAUXILIAIRE.OIDCOMPTEGENERAL AND
|
|
|
TECRITURE.OIDROLETIERS = w_TCOMPTEAUXILIAIRE.OIDROLETIERS
|
|
|
LEFT JOIN prod_sage100compta.TPOINTANALYTIQUE ON OIDSECTIONANALYTIQUELIGNE = TPOINTANALYTIQUE.OID
|
|
|
LEFT JOIN compta.t_sections_analytiques ON TPOINTANALYTIQUE.OIDSECTIONANALYTIQUE = t_sections_analytiques.code_original
|
|
|
LEFT JOIN compta.t_comptes t_comptes_contre ON t_comptes_contre.oid = -1
|
|
|
WHERE TYPEECRITURE <> 0 AND TPIECE.NATUREPIECE = 1 AND TPIECE.REFERENCE LIKE '%ture%'
|
|
|
ORDER BY TECRITURE.OID
|
|
|
;
|
|
|
|
|
|
|
|
|
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 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">
|
|
|
|
|
|
<condition><![CDATA[
|
|
|
"[MOISMODIFIES]" != "0"
|
|
|
]]></condition>
|
|
|
|
|
|
<NODE label="Récupération chiffrier">
|
|
|
<sqlcmd><![CDATA[
|
|
|
|
|
|
TRUNCATE compta.p_chiffrier_comptable;
|
|
|
|
|
|
INSERT INTO compta.p_chiffrier_comptable
|
|
|
(
|
|
|
mois_comptable,
|
|
|
site_id,
|
|
|
clinique_honoraire,
|
|
|
montant_debit,
|
|
|
montant_credit
|
|
|
)
|
|
|
SELECT
|
|
|
date_part('year',TPERIODE.DATEDEBUT) * 100 + date_part('month',TPERIODE.DATEDEBUT) AS mois_comptable,
|
|
|
t_sites.oid,
|
|
|
t_sites.clinique_honoraire,
|
|
|
SUM(CREDIT),
|
|
|
SUM(DEBIT)
|
|
|
FROM prod_sage100compta.TCUMULPERIODEJOURNAL
|
|
|
JOIN compta.t_sites ON OIDETABLISSEMENT = code_original
|
|
|
JOIN prod_sage100compta.TPERIODE ON OIDPERIODE = TPERIODE.OID
|
|
|
|
|
|
GROUP BY 1,2,3;
|
|
|
|
|
|
|
|
|
UPDATE compta.p_chiffrier_comptable SET
|
|
|
montant_debit = p_chiffrier_comptable.montant_debit - subview.DEBIT,
|
|
|
montant_credit = p_chiffrier_comptable.montant_credit - subview.CREDIT
|
|
|
FROM
|
|
|
(
|
|
|
SELECT
|
|
|
date_part('year',DATEDEBUT) * 100 + date_part('month',DATEDEBUT) AS mois_comptable,
|
|
|
t_sites.oid AS site_id,
|
|
|
t_sites.clinique_honoraire,
|
|
|
round(SUM(DEBIT),2) AS DEBIT,
|
|
|
round(SUM(CREDIT),2) AS CREDIT
|
|
|
FROM prod_sage100compta.TECRITURE
|
|
|
JOIN prod_sage100compta.TPIECE ON OIDPIECE = TPIECE.OID
|
|
|
JOIN prod_sage100compta.TPERIODE ON OIDPERIODE = TPERIODE.OID
|
|
|
JOIN compta.t_sites ON OIDETABLISSEMENT = t_sites.code_original
|
|
|
WHERE TYPEECRITURE = 0
|
|
|
GROUP BY 1,2,3
|
|
|
ORDER BY 1,2,3
|
|
|
) subview
|
|
|
WHERE p_chiffrier_comptable.mois_comptable = subview.mois_comptable AND
|
|
|
p_chiffrier_comptable.site_id = subview.site_id;
|
|
|
|
|
|
]]></sqlcmd>
|
|
|
</NODE>
|
|
|
|
|
|
|
|
|
</NODE>
|
|
|
|
|
|
<NODE name="PARAM" label="RECUPERATION DES PARAMETRES">
|
|
|
<NODE label="Champs selon version SAGE">
|
|
|
<sqlcmd><![CDATA[
|
|
|
SELECT base.cti_execute('ALTER TABLE prod_sage100compta.TCOMPTEGENERAL ADD COLUMN rupture1 text DEFAULT ''''.,COMMENT ON TABLE prod_sage100compta.TCOMPTEGENERAL IS ''''',1)
|
|
|
WHERE 'rupture1' NOT IN (SELECT column_name FROM information_schema.columns WHERE table_name = 'tcomptegeneral')
|
|
|
;
|
|
|
SELECT base.cti_execute('ALTER TABLE prod_sage100compta.TCOMPTEGENERAL ADD COLUMN rupture2 text DEFAULT ''''.,COMMENT ON TABLE prod_sage100compta.TCOMPTEGENERAL IS ''''',1)
|
|
|
WHERE 'rupture2' NOT IN (SELECT column_name FROM information_schema.columns WHERE table_name = 'tcomptegeneral')
|
|
|
;
|
|
|
SELECT base.cti_execute('ALTER TABLE prod_sage100compta.TCOMPTEGENERAL ADD COLUMN rupture3 text DEFAULT ''''.,COMMENT ON TABLE prod_sage100compta.TCOMPTEGENERAL IS ''''',1)
|
|
|
WHERE 'rupture3' NOT IN (SELECT column_name FROM information_schema.columns WHERE table_name = 'tcomptegeneral')
|
|
|
;
|
|
|
SELECT base.cti_execute('ALTER TABLE prod_sage100compta.TCOMPTEGENERAL ADD COLUMN rupture4 text DEFAULT ''''.,COMMENT ON TABLE prod_sage100compta.TCOMPTEGENERAL IS ''''',1)
|
|
|
WHERE 'rupture4' NOT IN (SELECT column_name FROM information_schema.columns WHERE table_name = 'tcomptegeneral')
|
|
|
;
|
|
|
SELECT base.cti_execute('ALTER TABLE prod_sage100compta.TCOMPTEGENERAL ADD COLUMN rupture5 text DEFAULT ''''.,COMMENT ON TABLE prod_sage100compta.TCOMPTEGENERAL IS ''''',1)
|
|
|
WHERE 'rupture5' NOT IN (SELECT column_name FROM information_schema.columns WHERE table_name = 'tcomptegeneral')
|
|
|
;
|
|
|
SELECT base.cti_execute('ALTER TABLE prod_sage100compta.TECRITURE ADD COLUMN OIDSECTIONANALYTIQUELIGNE text.,COMMENT ON TABLE prod_sage100compta.TECRITURE IS ''''',1)
|
|
|
WHERE 'oidsectionanalytiqueligne' NOT IN (SELECT column_name FROM information_schema.columns WHERE table_name = 'tecriture')
|
|
|
;
|
|
|
|
|
|
]]></sqlcmd>
|
|
|
</NODE>
|
|
|
<NODE label="Paramètres">
|
|
|
<sqlcmd><![CDATA[
|
|
|
|
|
|
-- Periode comptable
|
|
|
|
|
|
|
|
|
-- Site =
|
|
|
INSERT INTO compta.t_sites(code_original, code, texte, clinique_honoraire)
|
|
|
SELECT OID, substr(CODE,1,10), CAPTION, 'C'
|
|
|
FROM prod_sage100compta.TETABLISSEMENT
|
|
|
WHERE OID IN (SELECT OIDETABLISSEMENT FROM prod_sage100compta.TPIECE) AND
|
|
|
OID 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 'CLI', 'CLI', 'Clients', 'CLI'
|
|
|
UNION
|
|
|
SELECT 'FOU', 'FOU', 'Fournisseurs', '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_original, code, texte)
|
|
|
SELECT OID, CODE, CAPTION
|
|
|
FROM prod_sage100compta.TSECTIONANALYTIQUE
|
|
|
WHERE TSECTIONANALYTIQUE.OID NOT IN (SELECT code_original 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);
|
|
|
|
|
|
|
|
|
-- Journaux
|
|
|
|
|
|
INSERT INTO compta.t_journaux(code_original, code, texte, a_nouveaux, clinique_honoraire)
|
|
|
SELECT OID, CODE, CAPTION, '0', 'C'
|
|
|
FROM prod_sage100compta.TJOURNAL
|
|
|
WHERE TJOURNAL.OID NOT IN (SELECT code_original FROM compta.t_journaux WHERE code_original IS NOT NULL) AND
|
|
|
TJOURNAL.OID IN (SELECT OIDJOURNAL FROM prod_sage100compta.TPIECE)
|
|
|
ORDER BY 1;
|
|
|
|
|
|
-- Classes de comptes
|
|
|
INSERT INTO compta.t_classes_comptes(code, texte)
|
|
|
SELECT CODE, upper(CAPTION)
|
|
|
FROM prod_sage100compta.TCORRESPONDANCEGROUPECOMPTE
|
|
|
WHERE CAPTION <> '' AND
|
|
|
CODE NOT IN (SELECT code FROM compta.t_classes_comptes WHERE code IS NOT NULL)
|
|
|
ORDER BY CODE;
|
|
|
|
|
|
UPDATE compta.t_classes_comptes
|
|
|
SET texte = upper(CAPTION)
|
|
|
FROM prod_sage100compta.TCORRESPONDANCEGROUPECOMPTE
|
|
|
WHERE t_classes_comptes.code = TCORRESPONDANCEGROUPECOMPTE.CODE AND CAPTION <> '' AND
|
|
|
texte <> upper(CAPTION) ;
|
|
|
|
|
|
|
|
|
-- Comptes
|
|
|
UPDATE compta.t_comptes SET
|
|
|
type_compta_id = subview.type_compta_id,
|
|
|
texte = subview.texte
|
|
|
FROM
|
|
|
(
|
|
|
SELECT
|
|
|
COALESCE(t_types_compta.oid,0) AS type_compta_id,
|
|
|
TCOMPTEGENERAL.CODECOMPTE AS numero,
|
|
|
MAX(CAPTION) AS texte
|
|
|
FROM prod_sage100compta.TCOMPTEGENERAL
|
|
|
LEFT JOIN compta.t_types_compta ON
|
|
|
CASE
|
|
|
WHEN TCOMPTEGENERAL.CODECOMPTE LIKE '6%' OR TCOMPTEGENERAL.CODECOMPTE LIKE '7%' OR TCOMPTEGENERAL.CODECOMPTE LIKE '8%' THEN 'GES'
|
|
|
ELSE 'BIL' END
|
|
|
= t_types_compta.code_original
|
|
|
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
|
|
|
COALESCE(t_types_compta.oid,0) AS type_compta_id,
|
|
|
TCOMPTEGENERAL.CODECOMPTE AS numero,
|
|
|
MAX(CAPTION) AS texte,
|
|
|
0 AS compte_general_id,
|
|
|
'C' AS clinique_honoraire,
|
|
|
MAX(CASE WHEN TCOMPTEGENERAL.CODECOMPTE 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 prod_sage100compta.TCOMPTEGENERAL
|
|
|
LEFT JOIN compta.t_types_compta ON
|
|
|
CASE
|
|
|
WHEN TCOMPTEGENERAL.CODECOMPTE LIKE '6%' OR TCOMPTEGENERAL.CODECOMPTE LIKE '7%' OR TCOMPTEGENERAL.CODECOMPTE LIKE '8%' THEN 'GES'
|
|
|
ELSE 'BIL' END
|
|
|
= t_types_compta.code_original
|
|
|
WHERE TCOMPTEGENERAL.CODECOMPTE NOT IN (SELECT numero FROM compta.t_comptes WHERE numero IS NOT NULL) AND
|
|
|
TCOMPTEGENERAL.OID IN (SELECT OIDCOMPTEGENERAL FROM prod_sage100compta.TECRITURE)
|
|
|
GROUP BY 1,2
|
|
|
ORDER BY 2;
|
|
|
|
|
|
-- Partenaires
|
|
|
INSERT INTO compta.t_partenaires(code_original, code, texte, texte_court)
|
|
|
SELECT OIDTIERS, TTIERS.CODE, TTIERS.CAPTION, substr(TTIERS.CAPTION,1,50)
|
|
|
FROM prod_sage100compta.TROLETIERS
|
|
|
JOIN prod_sage100compta.TTIERS ON OIDTIERS = TTIERS.OID
|
|
|
WHERE TROLETIERS.OID IN (SELECT OIDROLETIERS FROM prod_sage100compta.TECRITURE) AND
|
|
|
OIDTIERS NOT IN (SELECT code_original FROM compta.t_partenaires WHERE code_original IS NOT NULL)
|
|
|
GROUP BY 1,2,3,4;
|
|
|
|
|
|
UPDATE compta.t_partenaires SET
|
|
|
code = TTIERS.CODE,
|
|
|
texte = TTIERS.CAPTION,
|
|
|
texte_court = substr(TTIERS.CAPTION,1,50)
|
|
|
FROM prod_sage100compta.TTIERS
|
|
|
WHERE TTIERS.OID = code_original AND
|
|
|
(t_partenaires.code IS DISTINCT FROM TTIERS.CODE OR
|
|
|
t_partenaires.texte IS DISTINCT FROM TTIERS.CAPTION OR
|
|
|
t_partenaires.texte_court IS DISTINCT FROM substr(TTIERS.CAPTION,1,50));
|
|
|
|
|
|
|
|
|
-- Comptes auxiliaires
|
|
|
DROP TABLE IF EXISTS w_TCOMPTEAUXILIAIRE;
|
|
|
CREATE TEMP TABLE w_TCOMPTEAUXILIAIRE AS
|
|
|
SELECT TCOMPTEAUXILIAIRE.OID,
|
|
|
OIDCOMPTEGENERAL,
|
|
|
TCOMPTEGENERAL.CODECOMPTE,
|
|
|
TCOMPTEGENERAL.CODECOMPTE || '.' || TTIERS.CODE AS CODECOMPTEAUXILIAIRE,
|
|
|
TTIERS.CAPTION,
|
|
|
OIDTIERS,
|
|
|
OIDROLETIERS,
|
|
|
0::bigint AS compte_auxiliaire_id,
|
|
|
0::bigint AS partenaire_id
|
|
|
FROM prod_sage100compta.TCOMPTEAUXILIAIRE
|
|
|
JOIN prod_sage100compta.TCOMPTEGENERAL ON OIDCOMPTEGENERAL = TCOMPTEGENERAL.OID
|
|
|
JOIN prod_sage100compta.TROLETIERS ON OIDROLETIERS = TROLETIERS.OID
|
|
|
JOIN prod_sage100compta.TTIERS ON OIDTIERS = TTIERS.OID;
|
|
|
|
|
|
UPDATE w_TCOMPTEAUXILIAIRE
|
|
|
SET partenaire_id = t_partenaires.oid
|
|
|
FROM compta.t_partenaires
|
|
|
WHERE OIDTIERS = t_partenaires.code_original;
|
|
|
|
|
|
|
|
|
UPDATE compta.t_comptes SET
|
|
|
type_compta_id = subview.type_compta_id,
|
|
|
texte = subview.texte,
|
|
|
compte_general_id = subview.compte_general_id,
|
|
|
partenaire_id = subview.partenaire_id
|
|
|
FROM
|
|
|
(
|
|
|
SELECT
|
|
|
COALESCE(t_types_compta.oid,0) AS type_compta_id,
|
|
|
CODECOMPTEAUXILIAIRE AS numero,
|
|
|
MAX(CAPTION) AS texte,
|
|
|
MAX(COALESCE(t_comptes.oid,0)) AS compte_general_id,
|
|
|
MAX(w_TCOMPTEAUXILIAIRE.partenaire_id) AS partenaire_id
|
|
|
FROM w_TCOMPTEAUXILIAIRE
|
|
|
LEFT JOIN compta.t_comptes ON CODECOMPTE = t_comptes.numero
|
|
|
LEFT JOIN compta.t_types_compta ON
|
|
|
CASE
|
|
|
WHEN CODECOMPTE LIKE '411%' THEN 'CLI'
|
|
|
WHEN CODECOMPTE LIKE '412%' THEN 'CLI'
|
|
|
WHEN CODECOMPTE LIKE '419%' THEN 'CLI'
|
|
|
ELSE 'DIV' END
|
|
|
= t_types_compta.code_original
|
|
|
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 OR
|
|
|
t_comptes.compte_general_id IS DISTINCT FROM subview.compte_general_id 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
|
|
|
COALESCE(t_types_compta.oid,0) AS type_compta_id,
|
|
|
CODECOMPTEAUXILIAIRE AS numero,
|
|
|
MAX(CAPTION) AS texte,
|
|
|
MAX(COALESCE(t_comptes.oid,0)) AS compte_general_id,
|
|
|
'C' AS clinique_honoraire,
|
|
|
'0' AS banque,
|
|
|
'0' AS collectif,
|
|
|
0 AS type_compta_extra_id,
|
|
|
'' AS numero_extra,
|
|
|
MAX(w_TCOMPTEAUXILIAIRE.partenaire_id) AS partenaire_id
|
|
|
FROM w_TCOMPTEAUXILIAIRE
|
|
|
LEFT JOIN compta.t_comptes ON CODECOMPTE = t_comptes.numero
|
|
|
LEFT JOIN compta.t_types_compta ON
|
|
|
CASE
|
|
|
WHEN CODECOMPTE LIKE '40%' THEN 'FOU'
|
|
|
WHEN CODECOMPTE LIKE '411%' THEN 'CLI'
|
|
|
WHEN CODECOMPTE LIKE '412%' THEN 'CLI'
|
|
|
WHEN CODECOMPTE LIKE '419%' THEN 'CLI'
|
|
|
ELSE 'DIV' END
|
|
|
= t_types_compta.code_original
|
|
|
WHERE OIDCOMPTEGENERAL IN (SELECT OIDCOMPTEGENERAL FROM prod_sage100compta.TECRITURE) AND
|
|
|
CODECOMPTEAUXILIAIRE NOT IN (SELECT numero FROM compta.t_comptes WHERE numero IS NOT NULL)
|
|
|
GROUP BY 1,2
|
|
|
ORDER BY 2;
|
|
|
|
|
|
|
|
|
UPDATE w_TCOMPTEAUXILIAIRE
|
|
|
SET compte_auxiliaire_id = t_comptes.oid
|
|
|
FROM compta.t_comptes
|
|
|
WHERE w_TCOMPTEAUXILIAIRE.CODECOMPTEAUXILIAIRE = t_comptes.numero;
|
|
|
|
|
|
|
|
|
|
|
|
UPDATE compta.t_comptes SET
|
|
|
compte_general_id = oid
|
|
|
WHERE compte_general_id = 0 OR compte_general_id IS NULL;
|
|
|
|
|
|
-- Ruptures SAGE
|
|
|
|
|
|
DROP TABLE IF EXISTS w_compte_rupture;
|
|
|
CREATE TEMP TABLE w_compte_rupture AS
|
|
|
SELECT CODECOMPTE,
|
|
|
RUPTURE_LEVEL,
|
|
|
'SAGERUPT'::text || RUPTURE_LEVEL::text||'C'::text AS classe_code,
|
|
|
0::bigint AS classe_id,
|
|
|
CASE RUPTURE_LEVEL
|
|
|
WHEN 1 THEN RUPTURE1
|
|
|
WHEN 2 THEN RUPTURE2
|
|
|
WHEN 3 THEN RUPTURE3
|
|
|
WHEN 4 THEN RUPTURE4
|
|
|
WHEN 5 THEN RUPTURE5
|
|
|
ELSE '' END AS section_code,
|
|
|
0::bigint AS section_id,
|
|
|
0::bigint AS compte_id
|
|
|
FROM
|
|
|
(
|
|
|
SELECT 1::integer AS RUPTURE_LEVEL
|
|
|
UNION
|
|
|
SELECT 2::integer AS RUPTURE_LEVEL
|
|
|
UNION
|
|
|
SELECT 3::integer AS RUPTURE_LEVEL
|
|
|
UNION
|
|
|
SELECT 4::integer AS RUPTURE_LEVEL
|
|
|
UNION
|
|
|
SELECT 5::integer AS RUPTURE_LEVEL
|
|
|
) subview
|
|
|
JOIN compta.t_listes_tables ON t_listes_tables.code = 'CPT'
|
|
|
JOIN prod_sage100compta.TCOMPTEGENERAL ON
|
|
|
(
|
|
|
RUPTURE_LEVEL = 1 AND RUPTURE1 <> '' OR
|
|
|
RUPTURE_LEVEL = 2 AND RUPTURE2 <> '' OR
|
|
|
RUPTURE_LEVEL = 3 AND RUPTURE3 <> '' OR
|
|
|
RUPTURE_LEVEL = 4 AND RUPTURE4 <> '' OR
|
|
|
RUPTURE_LEVEL = 5 AND RUPTURE5 <> ''
|
|
|
)
|
|
|
ORDER BY 1,2
|
|
|
;
|
|
|
|
|
|
UPDATE w_compte_rupture
|
|
|
SET compte_id = t_comptes.oid
|
|
|
FROM compta.t_comptes
|
|
|
WHERE t_comptes.numero = CODECOMPTE AND
|
|
|
t_comptes.compte_general_id = t_comptes.oid
|
|
|
;
|
|
|
|
|
|
|
|
|
INSERT INTO compta.t_classes(code, texte, table_id, is_cti, sequence, contenu_by_code, contenu_non_replicable_ailleurs)
|
|
|
SELECT classe_code,
|
|
|
'SAGE. Rupture '||RUPTURE_LEVEL::text,
|
|
|
subview.table_id,
|
|
|
'0'::text AS is_cti,
|
|
|
subview.max_sequence + RUPTURE_LEVEL,
|
|
|
'0'::text,
|
|
|
'1'::text
|
|
|
FROM w_compte_rupture
|
|
|
LEFT JOIN compta.t_classes ON classe_code = t_classes.code
|
|
|
JOIN
|
|
|
(
|
|
|
SELECT t_listes_tables.oid AS table_id, GREATEST(MAX(sequence),30) AS max_sequence
|
|
|
FROM compta.t_classes
|
|
|
JOIN compta.t_listes_tables ON t_listes_tables.code = 'CPT'
|
|
|
GROUP BY 1
|
|
|
) subview ON 1=1
|
|
|
WHERE t_classes.oid IS NULL
|
|
|
GROUP BY 1,2,3,4,5,6
|
|
|
;
|
|
|
|
|
|
UPDATE w_compte_rupture
|
|
|
SET classe_id = t_classes.oid
|
|
|
FROM compta.t_classes
|
|
|
WHERE t_classes.code = classe_code
|
|
|
;
|
|
|
|
|
|
|
|
|
INSERT INTO compta.t_classes_sections (code, texte, classe_id)
|
|
|
SELECT w_compte_rupture.section_code, w_compte_rupture.section_code, w_compte_rupture.classe_id
|
|
|
FROM w_compte_rupture
|
|
|
LEFT JOIN compta.t_classes_sections ON
|
|
|
t_classes_sections.classe_id = w_compte_rupture.classe_id AND
|
|
|
t_classes_sections.code = w_compte_rupture.section_code
|
|
|
WHERE t_classes_sections.oid IS NULL
|
|
|
GROUP BY 1,2,3
|
|
|
;
|
|
|
|
|
|
UPDATE w_compte_rupture
|
|
|
SET section_id = t_classes_sections.oid
|
|
|
FROM compta.t_classes_sections
|
|
|
WHERE t_classes_sections.classe_id = w_compte_rupture.classe_id AND
|
|
|
t_classes_sections.code = w_compte_rupture.section_code
|
|
|
;
|
|
|
|
|
|
DELETE FROM compta.t_classes_sections_elements
|
|
|
USING
|
|
|
(
|
|
|
SELECT t_classes_sections_elements.section_id, to_id
|
|
|
FROM compta.t_classes_sections_elements
|
|
|
JOIN compta.t_classes_sections ON section_id = t_classes_sections.oid
|
|
|
JOIN compta.t_classes ON classe_id = t_classes.oid
|
|
|
JOIN w_compte_rupture ON
|
|
|
t_classes_sections.classe_id = w_compte_rupture.classe_id AND
|
|
|
t_classes_sections_elements.to_id = w_compte_rupture.compte_id
|
|
|
WHERE t_classes_sections.classe_id IN (SELECT classe_id FROM w_compte_rupture) AND
|
|
|
t_classes_sections_elements.section_id <> w_compte_rupture.section_id AND
|
|
|
w_compte_rupture.section_id <> 0
|
|
|
) subview
|
|
|
WHERE t_classes_sections_elements.section_id = subview.section_id AND
|
|
|
t_classes_sections_elements.to_id = subview.to_id
|
|
|
;
|
|
|
|
|
|
INSERT INTO compta.t_classes_sections_elements (section_id, to_id)
|
|
|
SELECT w_compte_rupture.section_id, w_compte_rupture.compte_id
|
|
|
FROM w_compte_rupture
|
|
|
LEFT JOIN compta.t_classes_sections_elements ON
|
|
|
t_classes_sections_elements.section_id = w_compte_rupture.section_id AND
|
|
|
t_classes_sections_elements.to_id = w_compte_rupture.compte_id
|
|
|
WHERE w_compte_rupture.compte_id <> 0 AND
|
|
|
w_compte_rupture.section_id <> 0 AND
|
|
|
t_classes_sections_elements.section_id IS NULL
|
|
|
GROUP BY 1,2
|
|
|
;
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
]]></sqlcmd>
|
|
|
</NODE>
|
|
|
|
|
|
</NODE>
|
|
|
|
|
|
</ROOT>
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|