|
|
<?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, à terme ne remonter que le dernier exercice comptable (dernier de acpcliex)
|
|
|
TRUNCATE compta.p_historique_ecritures;
|
|
|
--DELETE FROM compta.p_historique_ecritures
|
|
|
--USING (SELECT to_char(MIN(DEXE),'YYYYMM') as date_debut_acropole, MAX(FEXE) as date_fin_acropole FROM prod_acd.acpcliex) sub
|
|
|
--WHERE mois_comptable >= date_debut_acropole;
|
|
|
|
|
|
|
|
|
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,
|
|
|
(ECRITURE.ECR_ANNEE || LPAD(ECRITURE.ECR_MOIS,2,'0') || LPAD(LIGNE_ECRITURE.LE_JOUR,2,'0'))::date AS date_ecriture,
|
|
|
(ECRITURE.ECR_ANNEE || LPAD(ECRITURE.ECR_MOIS,2,'0'))::bigint AS mois_comptable,
|
|
|
LE_CRE_ORG::numeric AS montant_credit,
|
|
|
LE_DEB_ORG::numeric AS montant_debit,
|
|
|
t_journaux.oid AS journal_id,
|
|
|
0 AS section_analytique_id,
|
|
|
COALESCE(t_sites.clinique_honoraire,'C'),
|
|
|
exercice_comptable,
|
|
|
t_comptes.type_compta_id,
|
|
|
COALESCE(t_comptes.oid,0),
|
|
|
'0' AS comptabilisee,
|
|
|
'0' AS fin_exercice,
|
|
|
'0' AS ajustement,
|
|
|
LIGNE_ECRITURE.LE_CODE AS cle_originale,
|
|
|
COALESCE(t_comptes_contre.oid,0) AS compte_contrepartie_id,
|
|
|
LIGNE_ECRITURE.LE_LIB AS texte,
|
|
|
'20991231' AS date_facture_fournisseur,
|
|
|
'' AS piece,
|
|
|
'' AS dossier,
|
|
|
'20991231' AS date_echeance,
|
|
|
0 AS journal_paiement_id,
|
|
|
0 AS mode_paiement_id,
|
|
|
'' AS numero_cheque,
|
|
|
COALESCE(t_sites.oid,0) AS site_id,
|
|
|
COALESCE(t_partenaires.oid,0),
|
|
|
'0' AS inter_site,
|
|
|
ECRITURE.ECR_CODE::text || '-'::text || LIGNE_ECRITURE.LE_ORDRE::text AS identifiant_operation
|
|
|
FROM prod_acd.ECRITURE
|
|
|
JOIN prod_acd.LIGNE_ECRITURE ON LIGNE_ECRITURE.ECR_CODE = ECRITURE.ECR_CODE
|
|
|
JOIN prod_acd.COMPTE ON LIGNE_ECRITURE.CPT_CODE = COMPTE.CPT_CODE
|
|
|
JOIN compta.t_comptes ON (CASE WHEN CPT_CATEG = 'G' THEN LIGNE_ECRITURE.CPT_CODE
|
|
|
WHEN CPT_CATEG = 'F' THEN '41100000_' || LIGNE_ECRITURE.CPT_CODE
|
|
|
WHEN CPT_CATEG = 'C' THEN '40100000_' || LIGNE_ECRITURE.CPT_CODE END = t_comptes.numero)
|
|
|
JOIN compta.t_journaux ON (ECRITURE.JNL_CODE = t_journaux.code_original)
|
|
|
LEFT JOIN compta.t_sites ON t_sites.oid = 0
|
|
|
JOIN base.p_calendrier_mois ON ECRITURE.ECR_ANNEE = annee AND ECRITURE.ECR_MOIS = numero_mois
|
|
|
LEFT JOIN compta.t_partenaires ON LIGNE_ECRITURE.CPT_CODE = t_partenaires.code
|
|
|
LEFT JOIN compta.t_comptes t_comptes_contre ON t_comptes_contre.oid = -1
|
|
|
LEFT JOIN prod_acd.ECRITURE_SUPPRIMEE ON ECRITURE_SUPPRIMEE.LE_CODE = LIGNE_ECRITURE.LE_CODE
|
|
|
WHERE (ECRITURE.ECR_ANNEE || LPAD(ECRITURE.ECR_MOIS,2,'0'))::bigint >= 200701
|
|
|
AND ECRITURE_SUPPRIMEE.LE_CODE IS NULL
|
|
|
|
|
|
;
|
|
|
|
|
|
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,
|
|
|
(HE_ANNEE || LPAD(HE_MOIS,2,'0') || LPAD(HLE_JOUR,2,'0'))::date AS date_ecriture,
|
|
|
(HE_ANNEE || LPAD(HE_MOIS,2,'0'))::bigint AS mois_comptable,
|
|
|
HLE_CRE_ORG::numeric AS montant_credit,
|
|
|
HLE_DEB_ORG::numeric AS montant_debit,
|
|
|
t_journaux.oid AS journal_id,
|
|
|
0 AS section_analytique_id,
|
|
|
COALESCE(t_sites.clinique_honoraire,'C'),
|
|
|
exercice_comptable,
|
|
|
t_comptes.type_compta_id,
|
|
|
COALESCE(t_comptes.oid,0),
|
|
|
'0' AS comptabilisee,
|
|
|
'0' AS fin_exercice,
|
|
|
'0' AS ajustement,
|
|
|
HLE_CODE AS cle_originale,
|
|
|
COALESCE(t_comptes_contre.oid,0) AS compte_contrepartie_id,
|
|
|
HLE_LIB AS texte,
|
|
|
'20991231' AS date_facture_fournisseur,
|
|
|
'' AS piece,
|
|
|
'' AS dossier,
|
|
|
'20991231' AS date_echeance,
|
|
|
0 AS journal_paiement_id,
|
|
|
0 AS mode_paiement_id,
|
|
|
'' AS numero_cheque,
|
|
|
COALESCE(t_sites.oid,0) AS site_id,
|
|
|
COALESCE(t_partenaires.oid,0),
|
|
|
'0' AS inter_site,
|
|
|
HISTO_ECRITURE.HE_CODE::text || '-'::text || HLE_ORDRE::text AS identifiant_operation
|
|
|
FROM prod_acd.HISTO_ECRITURE
|
|
|
JOIN prod_acd.HISTO_LIGNE_ECRITURE ON HISTO_ECRITURE.HE_CODE = HISTO_LIGNE_ECRITURE.HE_CODE
|
|
|
JOIN prod_acd.COMPTE ON HISTO_LIGNE_ECRITURE.CPT_CODE = COMPTE.CPT_CODE
|
|
|
JOIN compta.t_comptes ON (CASE WHEN CPT_CATEG = 'G' THEN HISTO_LIGNE_ECRITURE.CPT_CODE
|
|
|
WHEN CPT_CATEG = 'F' THEN '41100000_' || HISTO_LIGNE_ECRITURE.CPT_CODE
|
|
|
WHEN CPT_CATEG = 'C' THEN '40100000_' || HISTO_LIGNE_ECRITURE.CPT_CODE END = t_comptes.numero)
|
|
|
JOIN compta.t_journaux ON (JNL_CODE = t_journaux.code_original)
|
|
|
LEFT JOIN compta.t_sites ON t_sites.oid = 0
|
|
|
JOIN base.p_calendrier_mois ON HE_ANNEE = annee AND HE_MOIS = numero_mois
|
|
|
LEFT JOIN compta.t_partenaires ON HISTO_LIGNE_ECRITURE.CPT_CODE = t_partenaires.code
|
|
|
LEFT JOIN compta.t_comptes t_comptes_contre ON t_comptes_contre.oid = -1
|
|
|
WHERE (HISTO_ECRITURE.HE_ANNEE || LPAD(HISTO_ECRITURE.HE_MOIS,2,'0'))::bigint >= 200701
|
|
|
;
|
|
|
|
|
|
|
|
|
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_journaux
|
|
|
WHERE journal_id = t_journaux.oid
|
|
|
AND p_historique_ecritures.clinique_honoraire <> 'C'
|
|
|
AND t_journaux.code != 'HONO';
|
|
|
|
|
|
|
|
|
UPDATE compta.p_historique_ecritures
|
|
|
SET clinique_honoraire = 'H'
|
|
|
FROM compta.t_journaux
|
|
|
WHERE journal_id = t_journaux.oid
|
|
|
AND p_historique_ecritures.clinique_honoraire <> 'H'
|
|
|
AND t_journaux.code = 'HONO';
|
|
|
|
|
|
|
|
|
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 IS NULL OR
|
|
|
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 IS NULL OR
|
|
|
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 IS NULL OR
|
|
|
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[
|
|
|
|
|
|
|
|
|
|
|
|
]]></sqlcmd>
|
|
|
</NODE>
|
|
|
|
|
|
|
|
|
</NODE>
|
|
|
|
|
|
<NODE name="PARAM" label="RECUPERATION DES PARAMETRES">
|
|
|
|
|
|
<NODE label="Regroupement des tables source">
|
|
|
<sqlcmd><![CDATA[
|
|
|
|
|
|
|
|
|
|
|
|
]]></sqlcmd>
|
|
|
</NODE>
|
|
|
|
|
|
<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);
|
|
|
|
|
|
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 (exercice = année)
|
|
|
|
|
|
UPDATE base.p_calendrier_mois SET
|
|
|
exercice_comptable = subview.ECR_ANNEE::int
|
|
|
FROM (
|
|
|
SELECT
|
|
|
p_calendrier_mois.mois,
|
|
|
p_calendrier_mois.date_debut,
|
|
|
ECR_ANNEE
|
|
|
FROM base.p_calendrier_mois
|
|
|
JOIN (
|
|
|
SELECT
|
|
|
ECR_ANNEE,
|
|
|
ECR_MOIS
|
|
|
FROM
|
|
|
prod_acd.ECRITURE
|
|
|
) subview ON date_debut BETWEEN (ECR_ANNEE || LPAD(ECR_MOIS,2,'0') || '01')::date AND (ECR_ANNEE || LPAD(ECR_MOIS,2,'0') || '01')::date + interval '1 month' - interval '1 day'
|
|
|
) subview
|
|
|
WHERE p_calendrier_mois.mois = subview.mois AND
|
|
|
p_calendrier_mois.exercice_comptable IS DISTINCT FROM subview.ECR_ANNEE;
|
|
|
|
|
|
UPDATE base.p_calendrier_mois
|
|
|
SET exercice_mois_comptable_1 = subview.exercice_mois_comptable_1
|
|
|
FROM
|
|
|
(
|
|
|
SELECT exercice_comptable,
|
|
|
MIN(mois) AS exercice_mois_comptable_1
|
|
|
FROM base.p_calendrier_mois
|
|
|
GROUP BY 1
|
|
|
) subview
|
|
|
WHERE p_calendrier_mois.exercice_comptable = subview.exercice_comptable AND
|
|
|
p_calendrier_mois.exercice_mois_comptable_1 IS DISTINCT FROM subview.exercice_mois_comptable_1;
|
|
|
|
|
|
|
|
|
-- Sites - La distinction se fait dans la compta analytique
|
|
|
-- En attendant un site "non renseigné et crée"
|
|
|
-- Lignes non effectives (ELA), l'oid 0 est utilisé par la suite
|
|
|
INSERT INTO compta.t_sites(code, clinique_honoraire, code_original, texte)
|
|
|
SELECT 'NO_SITE', '', '', 'Non renseigné'
|
|
|
WHERE 1!=1;
|
|
|
|
|
|
|
|
|
-- 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);
|
|
|
|
|
|
-- Journaux
|
|
|
INSERT INTO compta.t_journaux(code, code_original, texte, a_nouveaux)
|
|
|
SELECT JNL_CODE, JNL_CODE, JNL_LIB, CASE WHEN JNL_NATURE = 0 THEN '1' ELSE '0' END
|
|
|
FROM prod_acd.JOURNAL
|
|
|
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 CPT_CODE, CPT_CODE, CPT_LIB, LEFT(CPT_LIB,50)
|
|
|
FROM prod_acd.COMPTE
|
|
|
WHERE CPT_CODE NOT IN (SELECT code_original FROM compta.t_partenaires)
|
|
|
AND CPT_CATEG != 'G'
|
|
|
ORDER BY 1;
|
|
|
|
|
|
-- 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.CPT_CODE, subview.CPT_LIB, '',
|
|
|
CASE WHEN subviewj.CPT_CODE LIKE '512%' THEN '1' ELSE '0' END
|
|
|
FROM
|
|
|
(
|
|
|
SELECT JOURNAL.JNL_CODE, CPT_CODE
|
|
|
FROM prod_acd.ECRITURE
|
|
|
JOIN prod_acd.LIGNE_ECRITURE ON LIGNE_ECRITURE.ECR_CODE = ECRITURE.ECR_CODE
|
|
|
JOIN prod_acd.JOURNAL ON ECRITURE.JNL_CODE = JOURNAL.JNL_CODE WHERE LE_CRE_ORG > 0 GROUP BY 1,2
|
|
|
UNION ALL
|
|
|
SELECT NULL, cpt_code FROM prod_acd.histo_ligne_ecriture
|
|
|
GROUP BY 1,2
|
|
|
|
|
|
) subviewj
|
|
|
LEFT JOIN
|
|
|
(SELECT
|
|
|
CASE WHEN CPT_CODE LIKE '6%' THEN 'GES'
|
|
|
WHEN CPT_CODE LIKE '7%' THEN 'GES'
|
|
|
WHEN CPT_CODE LIKE '8%' THEN 'RES'
|
|
|
ELSE 'BIL' END AS plc_type,
|
|
|
CPT_CODE,
|
|
|
CPT_LIB
|
|
|
FROM prod_acd.COMPTE WHERE CPT_CATEG = 'G') subview
|
|
|
ON subview.CPT_CODE = subviewj.CPT_CODE
|
|
|
JOIN compta.t_types_compta ON (plc_type = t_types_compta.code_original)
|
|
|
WHERE subview.CPT_CODE NOT IN (SELECT numero FROM compta.t_comptes)
|
|
|
GROUP BY 1,2,3,4,5
|
|
|
ORDER BY subview.CPT_CODE;
|
|
|
|
|
|
UPDATE compta.t_comptes SET
|
|
|
banque = CASE WHEN numero like '512%' THEN '1' ELSE '0' END
|
|
|
;
|
|
|
|
|
|
-- Comptes spécifiques ?
|
|
|
|
|
|
INSERT INTO compta.t_comptes(type_compta_id, numero, texte, compte_general_id, clinique_honoraire)
|
|
|
SELECT 0, '41100000', 'CTI Fournisseurs', 0, 'C' WHERE '41100000' NOT IN (SElECT numero FROM compta.t_comptes);
|
|
|
|
|
|
INSERT INTO compta.t_comptes(type_compta_id, numero, texte, compte_general_id, clinique_honoraire)
|
|
|
SELECT 0, '40100000', 'CTI Clients', 0, 'C' WHERE '40100000' NOT IN (SElECT numero FROM compta.t_comptes);
|
|
|
|
|
|
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
|
|
|
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 || t_partenaires.code::text, t_partenaires.texte, t_comptes.oid, '', coalesce(t_partenaires.oid,0)
|
|
|
FROM prod_acd.COMPTE
|
|
|
JOIN compta.t_comptes ON CPT_CATEG != 'G' AND (CASE WHEN CPT_CATEG = 'F' THEN '41100000' ELSE '40100000' END = t_comptes.numero)
|
|
|
JOIN compta.t_types_compta ON ('BIL' = t_types_compta.code_original)
|
|
|
JOIN compta.t_partenaires ON (CPT_CODE = t_partenaires.code_original)
|
|
|
WHERE t_comptes.numero::text || '_'::text || t_partenaires.code::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>
|