|
|
return: text
|
|
|
lang: plpgsql
|
|
|
parameters:
|
|
|
p0:
|
|
|
type: bigint
|
|
|
name: i_oid
|
|
|
src: |
|
|
|
DECLARE
|
|
|
result TEXT;
|
|
|
BEGIN
|
|
|
|
|
|
-- Table de travail
|
|
|
IF NOT EXISTS (SELECT * FROM pg_class WHERE relnamespace = pg_my_temp_schema() AND relname = 'w_cti_gen_budget') THEN
|
|
|
DROP TABLE IF EXISTS w_cti_gen_budget;
|
|
|
CREATE TEMP TABLE w_cti_gen_budget(
|
|
|
oid bigint,
|
|
|
import_ligne text,
|
|
|
import_compte_budgetaire text,
|
|
|
import_compte_texte text,
|
|
|
import_include_comptes text,
|
|
|
import_exclude_comptes text,
|
|
|
import_montant_exercice text,
|
|
|
import_type_ventilation text,
|
|
|
import_taux01 text,
|
|
|
import_taux02 text,
|
|
|
import_taux03 text,
|
|
|
import_taux04 text,
|
|
|
import_taux05 text,
|
|
|
import_taux06 text,
|
|
|
import_taux07 text,
|
|
|
import_taux08 text,
|
|
|
import_taux09 text,
|
|
|
import_taux10 text,
|
|
|
import_taux11 text,
|
|
|
import_taux12 text,
|
|
|
montant_exercice numeric,
|
|
|
taux01 numeric,
|
|
|
taux02 numeric,
|
|
|
taux03 numeric,
|
|
|
taux04 numeric,
|
|
|
taux05 numeric,
|
|
|
taux06 numeric,
|
|
|
taux07 numeric,
|
|
|
taux08 numeric,
|
|
|
taux09 numeric,
|
|
|
taux10 numeric,
|
|
|
taux11 numeric,
|
|
|
taux12 numeric,
|
|
|
import_section_analytique text
|
|
|
);
|
|
|
END IF;
|
|
|
|
|
|
|
|
|
-- lignes de budget issues du copier coller excel
|
|
|
TRUNCATE w_cti_gen_budget;
|
|
|
|
|
|
|
|
|
INSERT INTO w_cti_gen_budget(oid, import_ligne)
|
|
|
SELECT
|
|
|
oid,
|
|
|
trim(import_ligne) AS import_ligne
|
|
|
FROM
|
|
|
(
|
|
|
SELECT oid, unnest(data_array) AS import_ligne
|
|
|
FROM
|
|
|
(
|
|
|
SELECT
|
|
|
t_budget.oid, string_to_array(replace(import_data,E'\t','||'),E'\r') AS data_array
|
|
|
FROM compta.t_budget
|
|
|
WHERE is_actif = '1' AND
|
|
|
(
|
|
|
t_budget.oid = i_oid OR
|
|
|
i_oid = 0
|
|
|
)
|
|
|
) subview
|
|
|
) subview
|
|
|
WHERE trim(import_ligne) <> '';
|
|
|
|
|
|
-- Découpage champs
|
|
|
UPDATE w_cti_gen_budget SET
|
|
|
import_compte_budgetaire = trim(split_part(import_ligne,'||',1)),
|
|
|
import_compte_texte = trim(split_part(import_ligne,'||',2)),
|
|
|
import_include_comptes = trim(split_part(import_ligne,'||',3)),
|
|
|
import_exclude_comptes = trim(split_part(import_ligne,'||',4)),
|
|
|
import_montant_exercice = trim(split_part(import_ligne,'||',5)),
|
|
|
import_type_ventilation = trim(split_part(import_ligne,'||',6)),
|
|
|
import_taux01 = trim(split_part(import_ligne,'||',7)),
|
|
|
import_taux02 = trim(split_part(import_ligne,'||',8)),
|
|
|
import_taux03 = trim(split_part(import_ligne,'||',9)),
|
|
|
import_taux04 = trim(split_part(import_ligne,'||',10)),
|
|
|
import_taux05 = trim(split_part(import_ligne,'||',11)),
|
|
|
import_taux06 = trim(split_part(import_ligne,'||',12)),
|
|
|
import_taux07 = trim(split_part(import_ligne,'||',13)),
|
|
|
import_taux08 = trim(split_part(import_ligne,'||',14)),
|
|
|
import_taux09 = trim(split_part(import_ligne,'||',15)),
|
|
|
import_taux10 = trim(split_part(import_ligne,'||',16)),
|
|
|
import_taux11 = trim(split_part(import_ligne,'||',17)),
|
|
|
import_taux12 = trim(split_part(import_ligne,'||',18)),
|
|
|
import_section_analytique = trim(split_part(import_ligne,'||',19))
|
|
|
;
|
|
|
|
|
|
-- Champs numériques
|
|
|
UPDATE w_cti_gen_budget SET
|
|
|
montant_exercice = CASE WHEN import_montant_exercice <> '' THEN base.cti_to_number(translate(import_montant_exercice ,',€? ','.')) ELSE 0 END,
|
|
|
taux01 = CASE WHEN import_taux01 <> '' THEN base.cti_to_number(translate(import_taux01 ,',€? ','.')) ELSE 0 END,
|
|
|
taux02 = CASE WHEN import_taux02 <> '' THEN base.cti_to_number(translate(import_taux02 ,',€? ','.')) ELSE 0 END,
|
|
|
taux03 = CASE WHEN import_taux03 <> '' THEN base.cti_to_number(translate(import_taux03 ,',€? ','.')) ELSE 0 END,
|
|
|
taux04 = CASE WHEN import_taux04 <> '' THEN base.cti_to_number(translate(import_taux04 ,',€? ','.')) ELSE 0 END,
|
|
|
taux05 = CASE WHEN import_taux05 <> '' THEN base.cti_to_number(translate(import_taux05 ,',€? ','.')) ELSE 0 END,
|
|
|
taux06 = CASE WHEN import_taux06 <> '' THEN base.cti_to_number(translate(import_taux06 ,',€? ','.')) ELSE 0 END,
|
|
|
taux07 = CASE WHEN import_taux07 <> '' THEN base.cti_to_number(translate(import_taux07 ,',€? ','.')) ELSE 0 END,
|
|
|
taux08 = CASE WHEN import_taux08 <> '' THEN base.cti_to_number(translate(import_taux08 ,',€? ','.')) ELSE 0 END,
|
|
|
taux09 = CASE WHEN import_taux09 <> '' THEN base.cti_to_number(translate(import_taux09 ,',€? ','.')) ELSE 0 END,
|
|
|
taux10 = CASE WHEN import_taux10 <> '' THEN base.cti_to_number(translate(import_taux10 ,',€? ','.')) ELSE 0 END,
|
|
|
taux11 = CASE WHEN import_taux11 <> '' THEN base.cti_to_number(translate(import_taux11 ,',€? ','.')) ELSE 0 END,
|
|
|
taux12 = CASE WHEN import_taux12 <> '' THEN base.cti_to_number(translate(import_taux12 ,',€? ','.')) ELSE 0 END
|
|
|
;
|
|
|
|
|
|
-- Génération des tables budget
|
|
|
DELETE FROM compta.t_budget_compte
|
|
|
WHERE budget_id IN (SELECT oid FROM w_cti_gen_budget)
|
|
|
;
|
|
|
|
|
|
-- Budget structuré
|
|
|
INSERT INTO compta.t_budget_compte(
|
|
|
budget_id,
|
|
|
numero,
|
|
|
texte,
|
|
|
clinique_honoraire,
|
|
|
section_analytique_code,
|
|
|
include_numero,
|
|
|
exclude_numero,
|
|
|
montant_budget_exercice,
|
|
|
mode_ventilation,
|
|
|
taux_budget_mensuel)
|
|
|
SELECT
|
|
|
oid,
|
|
|
import_compte_budgetaire,
|
|
|
import_compte_texte,
|
|
|
'C'::text AS clinique_honoraire,
|
|
|
import_section_analytique,
|
|
|
import_include_comptes,
|
|
|
import_exclude_comptes,
|
|
|
montant_exercice,
|
|
|
import_type_ventilation,
|
|
|
Array[
|
|
|
taux01,
|
|
|
taux02,
|
|
|
taux03,
|
|
|
taux04,
|
|
|
taux05,
|
|
|
taux06,
|
|
|
taux07,
|
|
|
taux08,
|
|
|
taux09,
|
|
|
taux10,
|
|
|
taux11,
|
|
|
taux12
|
|
|
]
|
|
|
FROM w_cti_gen_budget
|
|
|
WHERE import_compte_budgetaire <> '' AND
|
|
|
import_compte_budgetaire BETWEEN '1' AND '99999999' AND
|
|
|
import_include_comptes <> ''
|
|
|
;
|
|
|
|
|
|
|
|
|
|
|
|
-- Ajout compte à zéro pour jointure budget
|
|
|
INSERT INTO compta.t_types_compta(
|
|
|
oid, code_original, code, texte, specialite)
|
|
|
SELECT 0, '', 'NR', 'Non renseigné', ''
|
|
|
WHERE 0 NOT IN (SELECT oid FROM compta.t_types_compta)
|
|
|
;
|
|
|
|
|
|
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)
|
|
|
;
|
|
|
|
|
|
INSERT INTO compta.t_comptes
|
|
|
(oid, type_compta_id, numero, texte, clinique_honoraire, compte_general_id)
|
|
|
SELECT 0, 0, '00000000', 'Non renseigné', 'C', 0
|
|
|
WHERE 0 NOT IN (SELECT oid FROM compta.t_comptes)
|
|
|
;
|
|
|
|
|
|
INSERT INTO compta.t_comptes(
|
|
|
type_compta_id, numero, texte, clinique_honoraire)
|
|
|
SELECT subview.type_compta_id,
|
|
|
t_budget_compte.numero,
|
|
|
t_budget_compte.texte,
|
|
|
t_budget_compte.clinique_honoraire
|
|
|
FROM compta.t_budget_compte
|
|
|
JOIN
|
|
|
(
|
|
|
SELECT
|
|
|
substr(numero,1,1) AS classe, MAX(type_compta_id) AS type_compta_id
|
|
|
FROM compta.t_comptes
|
|
|
WHERE oid = compte_general_id
|
|
|
GROUP BY 1
|
|
|
ORDER BY count(*) DESC
|
|
|
) subview ON substr(numero,1,1)= subview.classe
|
|
|
LEFT JOIN compta.t_comptes ON
|
|
|
t_budget_compte.numero = t_comptes.numero AND
|
|
|
subview.type_compta_id = t_comptes.type_compta_id
|
|
|
WHERE t_budget_compte.numero BETWEEN '1' AND '99999999' AND
|
|
|
t_comptes.oid IS NULL
|
|
|
;
|
|
|
|
|
|
UPDATE compta.t_comptes
|
|
|
SET compte_general_id = oid
|
|
|
WHERE (compte_general_id IS NULL OR compte_general_id = 0) AND
|
|
|
numero IN (SELECT numero FROM compta.t_budget_compte)
|
|
|
;
|
|
|
|
|
|
PERFORM compta.cti_reorganize_comptes_c();
|
|
|
|
|
|
PERFORM base.cti_update_classes('compta', 't_comptes_c', 'CPT','');
|
|
|
|
|
|
UPDATE compta.t_budget_compte
|
|
|
SET compte_budget_id = t_comptes.oid
|
|
|
FROM compta.t_comptes
|
|
|
WHERE t_budget_compte.numero = t_comptes.numero AND
|
|
|
t_budget_compte.numero BETWEEN '1' AND '99999999' AND
|
|
|
compte_budget_id IS DISTINCT FROM t_comptes.oid
|
|
|
;
|
|
|
|
|
|
|
|
|
|
|
|
-- Table d'association lignes budget - comptes
|
|
|
DROP TABLE IF EXISTS w_budget_compte_compte;
|
|
|
CREATE TEMP TABLE w_budget_compte_compte AS
|
|
|
SELECT t_budget_compte.oid AS in_budget_compte_id, t_comptes.oid AS in_compte_id
|
|
|
FROM compta.t_budget_compte
|
|
|
JOIN compta.t_comptes ON
|
|
|
t_comptes.numero ILIKE ANY (string_to_array(replace(include_numero,'*','%'),' ')) AND
|
|
|
NOT (t_comptes.numero ILIKE ANY (string_to_array(replace(exclude_numero,'*','%'),' ')))
|
|
|
;
|
|
|
|
|
|
|
|
|
INSERT INTO compta.t_budget_compte_compte
|
|
|
(budget_compte_id, compte_id)
|
|
|
SELECT in_budget_compte_id, in_compte_id
|
|
|
FROM w_budget_compte_compte
|
|
|
LEFT JOIN compta.t_budget_compte_compte ON
|
|
|
in_budget_compte_id = budget_compte_id AND
|
|
|
in_compte_id = compte_id
|
|
|
WHERE budget_compte_id IS NULL
|
|
|
;
|
|
|
|
|
|
DELETE FROM compta.t_budget_compte_compte
|
|
|
USING
|
|
|
(
|
|
|
SELECT budget_compte_id, compte_id
|
|
|
FROM compta.t_budget_compte_compte
|
|
|
LEFT JOIN w_budget_compte_compte ON
|
|
|
in_budget_compte_id = budget_compte_id AND
|
|
|
in_compte_id = compte_id
|
|
|
WHERE in_budget_compte_id IS NULL
|
|
|
) subview
|
|
|
WHERE t_budget_compte_compte.budget_compte_id = subview.budget_compte_id AND
|
|
|
t_budget_compte_compte.compte_id = subview.compte_id
|
|
|
;
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
UPDATE compta.p_historique_ecritures_total p_historique_ecritures
|
|
|
SET compte_budget_id = t_budget_compte.compte_budget_id
|
|
|
FROM compta.t_budget_compte_compte,
|
|
|
compta.t_budget_compte,
|
|
|
compta.t_budget
|
|
|
WHERE t_budget_compte_compte.compte_id = p_historique_ecritures.compte_id AND
|
|
|
t_budget_compte_compte.budget_compte_id = t_budget_compte.oid AND
|
|
|
t_budget_compte.budget_id = t_budget.oid AND
|
|
|
t_budget.exercice_comptable = p_historique_ecritures.exercice_comptable AND
|
|
|
t_budget.site_id = p_historique_ecritures.site_id AND
|
|
|
p_historique_ecritures.compte_budget_id IS DISTINCT FROM t_budget_compte.compte_budget_id
|
|
|
;
|
|
|
|
|
|
UPDATE compta.p_historique_ecritures
|
|
|
SET compte_budget_id = t_budget_compte.compte_budget_id
|
|
|
FROM compta.t_budget_compte_compte,
|
|
|
compta.t_budget_compte,
|
|
|
compta.t_budget
|
|
|
WHERE t_budget_compte_compte.compte_id = p_historique_ecritures.compte_id AND
|
|
|
t_budget_compte_compte.budget_compte_id = t_budget_compte.oid AND
|
|
|
t_budget_compte.budget_id = t_budget.oid AND
|
|
|
t_budget.exercice_comptable = p_historique_ecritures.exercice_comptable AND
|
|
|
t_budget.site_id = p_historique_ecritures.site_id AND
|
|
|
p_historique_ecritures.compte_budget_id IS DISTINCT FROM t_budget_compte.compte_budget_id
|
|
|
;
|
|
|
|
|
|
UPDATE compta.p_historique_ecritures_total
|
|
|
SET compte_budget_id = compte_nonsigne_id
|
|
|
FROM compta.t_comptes
|
|
|
WHERE compte_id = t_comptes.oid AND
|
|
|
(compte_budget_id = 0 OR compte_budget_id IS NULL)
|
|
|
;
|
|
|
|
|
|
UPDATE compta.p_historique_ecritures
|
|
|
SET compte_budget_id = compte_nonsigne_id
|
|
|
FROM compta.t_comptes
|
|
|
WHERE compte_id = t_comptes.oid AND
|
|
|
(compte_budget_id = 0 OR compte_budget_id IS NULL)
|
|
|
;
|
|
|
|
|
|
UPDATE compta.p_historique_ecritures_total
|
|
|
SET compte_budget_id = 0
|
|
|
WHERE compte_budget_id IS NULL
|
|
|
;
|
|
|
|
|
|
UPDATE compta.p_historique_ecritures
|
|
|
SET compte_budget_id = 0
|
|
|
WHERE compte_budget_id IS NULL
|
|
|
;
|
|
|
|
|
|
|
|
|
-- Ventilation mensuelle
|
|
|
|
|
|
-- Mois
|
|
|
UPDATE compta.t_budget
|
|
|
SET mois = subview.mois
|
|
|
FROM
|
|
|
(
|
|
|
SELECT oid, base.cti_array_accum(mois) AS mois
|
|
|
FROM
|
|
|
(
|
|
|
SELECT t_budget.oid, p_calendrier_mois.mois
|
|
|
FROM base.p_calendrier_mois
|
|
|
JOIN compta.t_budget ON t_budget.exercice_comptable = p_calendrier_mois.exercice_comptable
|
|
|
ORDER BY t_budget.oid, p_calendrier_mois.mois
|
|
|
) subview
|
|
|
GROUP BY 1
|
|
|
) subview
|
|
|
WHERE t_budget.oid = subview.oid AND
|
|
|
t_budget.mois IS DISTINCT FROM subview.mois
|
|
|
;
|
|
|
|
|
|
|
|
|
-- Taux de ventilation
|
|
|
|
|
|
-- Prorata temporis
|
|
|
UPDATE compta.t_budget_compte
|
|
|
SET taux_budget_mensuel =
|
|
|
ARRAY[
|
|
|
1.00/12,
|
|
|
1.00/12,
|
|
|
1.00/12,
|
|
|
1.00/12,
|
|
|
1.00/12,
|
|
|
1.00/12,
|
|
|
1.00/12,
|
|
|
1.00/12,
|
|
|
1.00/12,
|
|
|
1.00/12,
|
|
|
1.00/12,
|
|
|
1.00/12
|
|
|
]
|
|
|
WHERE mode_ventilation = '1'
|
|
|
;
|
|
|
|
|
|
|
|
|
|
|
|
--Saisonnalisé
|
|
|
|
|
|
UPDATE compta.t_budget_compte
|
|
|
SET taux_budget_mensuel = subview.taux_budget_mensuel
|
|
|
FROM
|
|
|
(
|
|
|
SELECT
|
|
|
t_budget_compte.oid,
|
|
|
t_budget_compte.numero,
|
|
|
Array[
|
|
|
base.cti_division(SUM(CASE WHEN mois_comptable+100 = t_budget.mois[1] THEN montant_debit-montant_credit ELSE 0 END),SUM(montant_debit-montant_credit)),
|
|
|
base.cti_division(SUM(CASE WHEN mois_comptable+100 = t_budget.mois[2] THEN montant_debit-montant_credit ELSE 0 END),SUM(montant_debit-montant_credit)),
|
|
|
base.cti_division(SUM(CASE WHEN mois_comptable+100 = t_budget.mois[3] THEN montant_debit-montant_credit ELSE 0 END),SUM(montant_debit-montant_credit)),
|
|
|
base.cti_division(SUM(CASE WHEN mois_comptable+100 = t_budget.mois[4] THEN montant_debit-montant_credit ELSE 0 END),SUM(montant_debit-montant_credit)),
|
|
|
base.cti_division(SUM(CASE WHEN mois_comptable+100 = t_budget.mois[5] THEN montant_debit-montant_credit ELSE 0 END),SUM(montant_debit-montant_credit)),
|
|
|
base.cti_division(SUM(CASE WHEN mois_comptable+100 = t_budget.mois[6] THEN montant_debit-montant_credit ELSE 0 END),SUM(montant_debit-montant_credit)),
|
|
|
base.cti_division(SUM(CASE WHEN mois_comptable+100 = t_budget.mois[7] THEN montant_debit-montant_credit ELSE 0 END),SUM(montant_debit-montant_credit)),
|
|
|
base.cti_division(SUM(CASE WHEN mois_comptable+100 = t_budget.mois[8] THEN montant_debit-montant_credit ELSE 0 END),SUM(montant_debit-montant_credit)),
|
|
|
base.cti_division(SUM(CASE WHEN mois_comptable+100 = t_budget.mois[9] THEN montant_debit-montant_credit ELSE 0 END),SUM(montant_debit-montant_credit)),
|
|
|
base.cti_division(SUM(CASE WHEN mois_comptable+100 = t_budget.mois[10] THEN montant_debit-montant_credit ELSE 0 END),SUM(montant_debit-montant_credit)),
|
|
|
base.cti_division(SUM(CASE WHEN mois_comptable+100 = t_budget.mois[11] THEN montant_debit-montant_credit ELSE 0 END),SUM(montant_debit-montant_credit)),
|
|
|
base.cti_division(SUM(CASE WHEN mois_comptable+100 = t_budget.mois[12] THEN montant_debit-montant_credit ELSE 0 END),SUM(montant_debit-montant_credit))
|
|
|
] AS taux_budget_mensuel,
|
|
|
SUM(montant_debit-montant_credit)
|
|
|
FROM compta.p_historique_ecritures
|
|
|
JOIN compta.t_budget ON p_historique_ecritures.exercice_comptable = t_budget.exercice_comptable -1
|
|
|
JOIN compta.t_budget_compte ON budget_id = t_budget.oid AND mode_ventilation = '2'
|
|
|
JOIN compta.t_budget_compte_compte ON t_budget_compte.oid = budget_compte_id
|
|
|
WHERE p_historique_ecritures.compte_id = t_budget_compte_compte.compte_id AND
|
|
|
is_budget IS DISTINCT FROM '1'
|
|
|
GROUP BY 1,2
|
|
|
) subview
|
|
|
WHERE t_budget_compte.oid = subview.oid
|
|
|
;
|
|
|
|
|
|
-- Montant saisis
|
|
|
|
|
|
UPDATE compta.t_budget_compte
|
|
|
SET taux_budget_mensuel =
|
|
|
ARRAY[
|
|
|
base.cti_division(taux_budget_mensuel[1],montant_budget_exercice),
|
|
|
base.cti_division(taux_budget_mensuel[2],montant_budget_exercice),
|
|
|
base.cti_division(taux_budget_mensuel[3],montant_budget_exercice),
|
|
|
base.cti_division(taux_budget_mensuel[4],montant_budget_exercice),
|
|
|
base.cti_division(taux_budget_mensuel[5],montant_budget_exercice),
|
|
|
base.cti_division(taux_budget_mensuel[6],montant_budget_exercice),
|
|
|
base.cti_division(taux_budget_mensuel[7],montant_budget_exercice),
|
|
|
base.cti_division(taux_budget_mensuel[8],montant_budget_exercice),
|
|
|
base.cti_division(taux_budget_mensuel[9],montant_budget_exercice),
|
|
|
base.cti_division(taux_budget_mensuel[10],montant_budget_exercice),
|
|
|
base.cti_division(taux_budget_mensuel[11],montant_budget_exercice),
|
|
|
base.cti_division(taux_budget_mensuel[12],montant_budget_exercice)
|
|
|
]
|
|
|
WHERE mode_ventilation = '8'
|
|
|
;
|
|
|
|
|
|
|
|
|
-- Ajustement dernier mois (arrondis)
|
|
|
UPDATE compta.t_budget_compte SET
|
|
|
montant_budget_mensuel =
|
|
|
ARRAY[
|
|
|
round(montant_budget_exercice * taux_budget_mensuel[1],2),
|
|
|
round(montant_budget_exercice * taux_budget_mensuel[2],2),
|
|
|
round(montant_budget_exercice * taux_budget_mensuel[3],2),
|
|
|
round(montant_budget_exercice * taux_budget_mensuel[4],2),
|
|
|
round(montant_budget_exercice * taux_budget_mensuel[5],2),
|
|
|
round(montant_budget_exercice * taux_budget_mensuel[6],2),
|
|
|
round(montant_budget_exercice * taux_budget_mensuel[7],2),
|
|
|
round(montant_budget_exercice * taux_budget_mensuel[8],2),
|
|
|
round(montant_budget_exercice * taux_budget_mensuel[9],2),
|
|
|
round(montant_budget_exercice * taux_budget_mensuel[10],2),
|
|
|
round(montant_budget_exercice * taux_budget_mensuel[11],2),
|
|
|
0.00
|
|
|
]
|
|
|
;
|
|
|
|
|
|
UPDATE compta.t_budget_compte SET
|
|
|
montant_budget_mensuel[12] =
|
|
|
montant_budget_exercice -
|
|
|
montant_budget_mensuel[1] -
|
|
|
montant_budget_mensuel[2] -
|
|
|
montant_budget_mensuel[3] -
|
|
|
montant_budget_mensuel[4] -
|
|
|
montant_budget_mensuel[5] -
|
|
|
montant_budget_mensuel[6] -
|
|
|
montant_budget_mensuel[7] -
|
|
|
montant_budget_mensuel[8] -
|
|
|
montant_budget_mensuel[9] -
|
|
|
montant_budget_mensuel[10] -
|
|
|
montant_budget_mensuel[11]
|
|
|
;
|
|
|
|
|
|
-- Génération en comptabilité
|
|
|
DELETE FROM compta.p_historique_ecritures
|
|
|
WHERE is_budget = '1'
|
|
|
;
|
|
|
|
|
|
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,
|
|
|
texte,
|
|
|
date_facture_fournisseur,
|
|
|
date_echeance,
|
|
|
numero_cheque,
|
|
|
site_id,
|
|
|
is_budget,
|
|
|
compte_budget_id)
|
|
|
SELECT
|
|
|
t_budget_compte.compte_budget_id,
|
|
|
(t_budget.mois[i]||'01')::date AS date_ecriture,
|
|
|
t_budget.mois[i] AS mois_comptable,
|
|
|
CASE WHEN t_budget_compte.numero LIKE '7%' OR t_budget_compte.numero BETWEEN '1' AND '59999999' OR t_budget_compte.numero BETWEEN '8' AND '99999999' AND montant_budget_mensuel[i] > 0 THEN montant_budget_mensuel[i] ELSE 0 END AS montant_credit,
|
|
|
CASE WHEN t_budget_compte.numero LIKE '6%' OR t_budget_compte.numero BETWEEN '1' AND '59999999' OR t_budget_compte.numero BETWEEN '8' AND '99999999' AND montant_budget_mensuel[i] < 0 THEN 0-montant_budget_mensuel[i] ELSE 0 END AS montant_debit,
|
|
|
0::bigint AS journal_id,
|
|
|
COALESCE(t_sections_analytiques.oid,0::bigint) AS section_analytique_id,
|
|
|
t_budget_compte.clinique_honoraire,
|
|
|
t_budget.exercice_comptable,
|
|
|
t_comptes.type_compta_id,
|
|
|
t_budget_compte.compte_budget_id AS compte_extra_id,
|
|
|
'0'::text AS comptabilisee,
|
|
|
'0'::text AS fin_exercice,
|
|
|
'0'::text AS ajustement,
|
|
|
t_budget.oid AS cle_originale,
|
|
|
'Budget ' || t_budget.exercice_comptable || ' ' || t_budget.texte,
|
|
|
'20991231'::date AS date_facture_fournisseur,
|
|
|
'20991231'::date AS date_echeance,
|
|
|
''::text AS numero_cheque,
|
|
|
t_budget.site_id,
|
|
|
'1'::text AS is_budget,
|
|
|
t_budget_compte.compte_budget_id
|
|
|
FROM compta.t_budget
|
|
|
JOIN compta.t_budget_compte ON budget_id = t_budget.oid
|
|
|
JOIN compta.t_comptes ON t_budget_compte.compte_budget_id = t_comptes.oid
|
|
|
LEFT JOIN compta.t_sections_analytiques ON t_budget_compte.section_analytique_code = t_sections_analytiques.code AND t_budget_compte.section_analytique_code <> ''
|
|
|
JOIN (
|
|
|
SELECT generate_series(1,12) AS i
|
|
|
) subview ON 1=1
|
|
|
WHERE is_actif = '1'
|
|
|
;
|
|
|
|
|
|
-- Regénération écritures 'total'
|
|
|
DELETE FROM compta.p_historique_ecritures_total WHERE is_budget = '1' ;
|
|
|
INSERT INTO compta.p_historique_ecritures_total(
|
|
|
compte_id, mois_comptable, montant_credit, montant_debit, journal_id,
|
|
|
section_analytique_id, clinique_honoraire, exercice_comptable,
|
|
|
type_compta_id, site_id, compte_extra_id, partenaire_id, comptabilisee, fin_exercice,
|
|
|
ajustement, inter_site, ecriture_consolidee,
|
|
|
is_budget,
|
|
|
compte_budget_id,
|
|
|
nombre_ecritures)
|
|
|
SELECT
|
|
|
compte_id, mois_comptable, montant_credit, montant_debit, journal_id,
|
|
|
section_analytique_id, clinique_honoraire, exercice_comptable,
|
|
|
type_compta_id, site_id, compte_extra_id, partenaire_id, comptabilisee, fin_exercice,
|
|
|
ajustement, inter_site, ecriture_consolidee,
|
|
|
is_budget,
|
|
|
compte_budget_id,
|
|
|
1
|
|
|
FROM compta.p_historique_ecritures
|
|
|
WHERE is_budget = '1'
|
|
|
;
|
|
|
|
|
|
-- Ajout des oid des comptes budgetaires
|
|
|
INSERT INTO compta.p_oids (code_table, oid)
|
|
|
SELECT 'comptes_budget_c', compte_budget_id
|
|
|
FROM compta.p_historique_ecritures_total
|
|
|
WHERE clinique_honoraire = 'C'
|
|
|
AND compte_budget_id NOT IN (SELECT oid FROM compta.p_oids WHERE code_table = 'comptes_budget_c')
|
|
|
GROUP BY 1,2;
|
|
|
|
|
|
|
|
|
RETURN 'OK';
|
|
|
END;
|