You can not select more than 25 topics Topics must start with a letter or number, can include dashes ('-') and can be up to 35 characters long.
 
 

249 lines
14 KiB

return: text
lang: plpgsql
src: |
DECLARE result TEXT;
BEGIN
IF NOT EXISTS (SELECT * FROM activite.t_service_rubrique_dotation) THEN
return 'Pas de dotation paramétrée';
END IF;
-- Calcul coefficient dotation/facture
DELETE FROM activite.p_factures_lignes_c
WHERE rubrique_facturation_id <> 0 AND
rubrique_facturation_id IN (SELECT to_rubrique_facturation_id FROM activite.t_service_rubrique_dotation WHERE to_rubrique_facturation_id <> 0)
;
DROP TABLE IF EXISTS w_apply_dotation_new;
CREATE TEMP TABLE w_apply_dotation_new AS
SELECT p_factures_lignes_c.*,
to_prestation_id,
to_rubrique_facturation_id
FROM activite.p_factures_lignes_c
JOIN activite.t_lieux ON lieu_id = t_lieux.oid
JOIN activite.t_service_rubrique_dotation ON
t_lieux.service_facturation_id = ANY(t_service_rubrique_dotation.service_facturation_id_array) AND
p_factures_lignes_c.rubrique_facturation_id = ANY(t_service_rubrique_dotation.rubrique_facturation_id_array) AND
date_part('year',p_factures_lignes_c.date_fin) = t_service_rubrique_dotation.annee
WHERE t_service_rubrique_dotation.to_prestation_id <> 0
;
UPDATE w_apply_dotation_new SET
rubrique_facturation_id = to_rubrique_facturation_id,
rubrique_comptabilisation_id = to_rubrique_facturation_id,
prestation_id = to_prestation_id,
montant_facture_1 = montant_facture,
montant_facture_2 = 0,
montant_facture_22 = 0,
montant_facture_0 = 0,
montant_comptabilise = 0,
montant_comptabilise_1 = 0,
montant_comptabilise_2 = 0,
montant_comptabilise_22 = 0
;
ALTER TABLE w_apply_dotation_new DROP COLUMN to_rubrique_facturation_id;
ALTER TABLE w_apply_dotation_new DROP COLUMN to_prestation_id;
INSERT INTO activite.p_factures_lignes_c
SELECT *
FROM w_apply_dotation_new
;
DROP TABLE IF EXISTS w_apply_dotation;
CREATE TEMP TABLE w_apply_dotation AS
SELECT t_service_rubrique_dotation.oid AS dotation_id,
t_service_rubrique_dotation.service_facturation_id_array,
t_service_rubrique_dotation.rubrique_facturation_id_array,
annee,
SUM(nb_rubrique) AS nb_rubrique_tot,
SUM(CASE WHEN p_factures_lignes_c.montant_facture_1 <> 0 AND montant_comptabilise_1 = 0 THEN montant_facture_1 ELSE 0 END) +
SUM(CASE WHEN p_factures_lignes_c.montant_facture_2 <> 0 AND montant_comptabilise_1 = 0 THEN montant_facture_2 ELSE 0 END) +
SUM(CASE WHEN p_factures_lignes_c.montant_facture_22 <> 0 AND montant_comptabilise_1 = 0 THEN montant_facture_22 ELSE 0 END) +
SUM(p_factures_lignes_c.montant_encours) AS montant_fac_tot,
MAX(t_service_rubrique_dotation.montant_dotation*CASE WHEN date_part('year',now()) > annee THEN 1 ELSE (date(now()) - to_date(annee,'YYYY'))/365.00 END) As montant_dot,
0::numeric AS coefficient_dot
FROM activite.p_factures_lignes_c
JOIN activite.t_rubriques_facturation ON
rubrique_facturation_id = t_rubriques_facturation.oid
JOIN activite.t_lieux ON lieu_id = t_lieux.oid
JOIN activite.t_service_rubrique_dotation ON
t_lieux.service_facturation_id = ANY(t_service_rubrique_dotation.service_facturation_id_array) AND
p_factures_lignes_c.rubrique_facturation_id = ANY(t_service_rubrique_dotation.rubrique_facturation_id_array) AND
date_part('year',p_factures_lignes_c.date_fin) = t_service_rubrique_dotation.annee
WHERE (p_factures_lignes_c.montant_facture_1 <> 0 AND montant_comptabilise_1 = 0 OR
p_factures_lignes_c.montant_facture_2 <> 0 AND montant_comptabilise_2 = 0 OR
p_factures_lignes_c.montant_facture_22 <> 0 AND montant_comptabilise_22 = 0 OR
p_factures_lignes_c.montant_encours <> 0
) AND
t_service_rubrique_dotation.to_prestation_id = 0
GROUP BY 1,2,3,4;
INSERT INTO w_apply_dotation
SELECT t_service_rubrique_dotation.oid AS dotation_id,
t_service_rubrique_dotation.service_facturation_id_array,
ARRAY[to_rubrique_facturation_id],
annee,
SUM(nb_rubrique) AS nb_rubrique_tot,
SUM(CASE WHEN p_factures_lignes_c.montant_facture_1 <> 0 AND montant_comptabilise_1 = 0 THEN montant_facture_1 ELSE 0 END) +
SUM(CASE WHEN p_factures_lignes_c.montant_facture_2 <> 0 AND montant_comptabilise_1 = 0 THEN montant_facture_2 ELSE 0 END) +
SUM(CASE WHEN p_factures_lignes_c.montant_facture_22 <> 0 AND montant_comptabilise_1 = 0 THEN montant_facture_22 ELSE 0 END) +
SUM(p_factures_lignes_c.montant_encours) AS montant_fac_tot,
MAX(t_service_rubrique_dotation.montant_dotation*CASE WHEN date_part('year',now()) > annee THEN 1 ELSE (date(now()) - to_date(annee,'YYYY'))/365.00 END) As montant_dot,
0::numeric AS coefficient_dot
FROM activite.p_factures_lignes_c
JOIN activite.t_rubriques_facturation ON
rubrique_facturation_id = t_rubriques_facturation.oid
JOIN activite.t_lieux ON lieu_id = t_lieux.oid
JOIN activite.t_service_rubrique_dotation ON
t_lieux.service_facturation_id = ANY(t_service_rubrique_dotation.service_facturation_id_array) AND
p_factures_lignes_c.rubrique_facturation_id = to_rubrique_facturation_id AND
date_part('year',p_factures_lignes_c.date_fin) = t_service_rubrique_dotation.annee
WHERE (p_factures_lignes_c.montant_facture_1 <> 0 AND montant_comptabilise_1 = 0 OR
p_factures_lignes_c.montant_facture_2 <> 0 AND montant_comptabilise_2 = 0 OR
p_factures_lignes_c.montant_facture_22 <> 0 AND montant_comptabilise_22 = 0 OR
p_factures_lignes_c.montant_encours <> 0
) AND
t_service_rubrique_dotation.to_rubrique_facturation_id <> 0
GROUP BY 1,2,3,4;
UPDATE w_apply_dotation
SET coefficient_dot = base.cti_division(montant_dot,montant_fac_tot)
;
-- Application coefficient
UPDATE activite.p_factures_lignes_c SET
montant_facture_1 = CASE WHEN p_factures_lignes_c.montant_facture_1 <> 0 AND p_factures_lignes_c.montant_comptabilise_1 = 0 THEN p_factures_lignes_c.montant_facture_1 * coefficient_dot ELSE 0 END ,
montant_comptabilise_budget_global_1 = CASE WHEN p_factures_lignes_c.montant_facture_1 <> 0 AND p_factures_lignes_c.montant_comptabilise_1 = 0 THEN p_factures_lignes_c.montant_facture_1 * coefficient_dot ELSE 0 END ,
montant_facture_2 = CASE WHEN p_factures_lignes_c.montant_facture_2 <> 0 AND p_factures_lignes_c.montant_comptabilise_2 = 0 THEN p_factures_lignes_c.montant_facture_2 * coefficient_dot ELSE 0 END ,
montant_facture_22 = CASE WHEN p_factures_lignes_c.montant_facture_22 <> 0 AND p_factures_lignes_c.montant_comptabilise_22 = 0 THEN p_factures_lignes_c.montant_facture_22 * coefficient_dot ELSE 0 END ,
montant_facture = montant_facture_0 +
CASE WHEN p_factures_lignes_c.montant_facture_1 <> 0 AND p_factures_lignes_c.montant_comptabilise_1 = 0 THEN p_factures_lignes_c.montant_facture_1 * coefficient_dot ELSE 0 END +
CASE WHEN p_factures_lignes_c.montant_facture_2 <> 0 AND p_factures_lignes_c.montant_comptabilise_2 = 0 THEN p_factures_lignes_c.montant_facture_2 * coefficient_dot ELSE 0 END +
CASE WHEN p_factures_lignes_c.montant_facture_22 <> 0 AND p_factures_lignes_c.montant_comptabilise_22 = 0 THEN p_factures_lignes_c.montant_facture_22 * coefficient_dot ELSE 0 END,
montant_encours = CASE WHEN p_factures_lignes_c.montant_encours <> 0 THEN p_factures_lignes_c.montant_encours * coefficient_dot ELSE 0 END,
prix_unitaire =
base.cti_division
(
montant_facture_0 +
CASE WHEN p_factures_lignes_c.montant_facture_1 <> 0 AND p_factures_lignes_c.montant_comptabilise_1 = 0 THEN p_factures_lignes_c.montant_facture_1 * coefficient_dot ELSE 0 END +
CASE WHEN p_factures_lignes_c.montant_facture_2 <> 0 AND p_factures_lignes_c.montant_comptabilise_2 = 0 THEN p_factures_lignes_c.montant_facture_2 * coefficient_dot ELSE 0 END +
CASE WHEN p_factures_lignes_c.montant_facture_22 <> 0 AND p_factures_lignes_c.montant_comptabilise_22 = 0 THEN p_factures_lignes_c.montant_facture_22 * coefficient_dot ELSE 0 END +
CASE WHEN p_factures_lignes_c.montant_encours <> 0 THEN p_factures_lignes_c.montant_encours * coefficient_dot ELSE 0 END
,
nb_rubrique
)
FROM w_apply_dotation, activite.t_lieux
WHERE p_factures_lignes_c.lieu_id = t_lieux.oid AND
t_lieux.service_facturation_id = ANY(w_apply_dotation.service_facturation_id_array) AND
p_factures_lignes_c.rubrique_facturation_id = ANY(w_apply_dotation.rubrique_facturation_id_array) AND
date_part('year',p_factures_lignes_c.date_fin) = w_apply_dotation.annee
;
-- Arrondi sur une ligne
UPDATE activite.p_factures_lignes_c SET
montant_facture = montant_facture + round_montant,
montant_facture_1 = CASE WHEN montant_facture_1 <> 0 AND montant_comptabilise_1 = 0 THEN montant_facture_1 + round_montant ELSE montant_facture_1 END,
montant_comptabilise_budget_global_1 = CASE WHEN montant_facture_1 <> 0 AND montant_comptabilise_1 = 0 THEN montant_facture_1 + round_montant ELSE montant_facture_1 END,
montant_facture_2 = CASE WHEN (montant_facture_1 = 0 OR montant_comptabilise_1 <> 0) AND montant_facture_2 <> 0 AND montant_comptabilise_2 = 0 THEN montant_facture_2 + round_montant ELSE montant_facture_2 END,
montant_facture_22 = CASE WHEN (montant_facture_1 = 0 OR montant_comptabilise_1 <> 0) AND (montant_facture_2 = 0 OR montant_comptabilise_2 <> 0) AND montant_facture_22 <> 0 AND montant_comptabilise_22 = 0 THEN montant_facture_22 + round_montant ELSE montant_facture_22 END
FROM
(
SELECT dotation_id,
MAX(montant_dot) -
(
SUM(CASE WHEN p_factures_lignes_c.montant_facture_1 <> 0 AND montant_comptabilise_1 = 0 THEN montant_facture_1 ELSE 0 END) +
SUM(CASE WHEN p_factures_lignes_c.montant_facture_2 <> 0 AND montant_comptabilise_1 = 0 THEN montant_facture_2 ELSE 0 END) +
SUM(CASE WHEN p_factures_lignes_c.montant_facture_22 <> 0 AND montant_comptabilise_1 = 0 THEN montant_facture_22 ELSE 0 END) +
SUM(p_factures_lignes_c.montant_encours)
) AS round_montant,
MAX(CASE
WHEN p_factures_lignes_c.montant_facture_1 <> 0 AND montant_comptabilise_1 = 0 THEN p_factures_lignes_c.CTID
WHEN p_factures_lignes_c.montant_facture_2 <> 0 AND montant_comptabilise_2 = 0 THEN p_factures_lignes_c.CTID
WHEN p_factures_lignes_c.montant_facture_22 <> 0 AND montant_comptabilise_22 = 0 THEN p_factures_lignes_c.CTID
ELSE NULL END) AS round_ctid
FROM activite.p_factures_lignes_c
JOIN activite.t_lieux ON lieu_id = t_lieux.oid
JOIN w_apply_dotation ON
t_lieux.service_facturation_id = ANY(w_apply_dotation.service_facturation_id_array) AND
p_factures_lignes_c.rubrique_facturation_id = ANY(w_apply_dotation.rubrique_facturation_id_array) AND
date_part('year',p_factures_lignes_c.date_fin) = w_apply_dotation.annee
WHERE (p_factures_lignes_c.montant_facture_1 <> 0 AND montant_comptabilise_1 = 0 OR
p_factures_lignes_c.montant_facture_2 <> 0 AND montant_comptabilise_2 = 0 OR
p_factures_lignes_c.montant_facture_22 <> 0 AND montant_comptabilise_22 = 0 OR
p_factures_lignes_c.montant_encours <> 0
)
GROUP BY 1
) subview
WHERE p_factures_lignes_c.CTID = subview.round_ctid;
-- Mise a jour entetes
DROP TABLE IF EXISTS w_apply_dotation_factures;
CREATE TEMP TABLE w_apply_dotation_factures AS
SELECT p_factures.no_facture,
SUM(montant_facture) AS montant_facture_c,
SUM(montant_facture_1) AS montant_facture_1_c,
SUM(montant_facture_2) AS montant_facture_2_c,
SUM(montant_facture_22) AS montant_facture_22_c,
SUM(montant_encours) AS montant_encours_c
FROM activite.p_factures_lignes_c
JOIN activite.p_factures ON p_factures.no_facture = p_factures_lignes_c.no_facture
JOIN w_apply_dotation ON
p_factures_lignes_c.rubrique_facturation_id = ANY(w_apply_dotation.rubrique_facturation_id_array) AND
date_part('year',p_factures_lignes_c.date_fin) = w_apply_dotation.annee
GROUP BY 1
;
UPDATE activite.p_factures SET
montant_facture_c = w_apply_dotation_factures.montant_facture_c,
montant_facture_1_c = w_apply_dotation_factures.montant_facture_1_c,
montant_comptabilise_budget_global_c = w_apply_dotation_factures.montant_facture_1_c,
montant_facture_2_c = w_apply_dotation_factures.montant_facture_2_c,
montant_facture_22_c = w_apply_dotation_factures.montant_facture_22_c,
montant_encours_c = w_apply_dotation_factures.montant_encours_c
FROM w_apply_dotation_factures
WHERE p_factures.no_facture = w_apply_dotation_factures.no_facture
;
DROP TABLE IF EXISTS w_apply_dotation_factures;
CREATE TEMP TABLE w_apply_dotation_factures AS
SELECT p_factures.no_facture_reference,
SUM(montant_facture) AS montant_facture_c,
SUM(montant_facture_1) AS montant_facture_1_c,
SUM(montant_facture_2) AS montant_facture_2_c,
SUM(montant_facture_22) AS montant_facture_22_c,
SUM(montant_encours) AS montant_encours_c
FROM activite.p_factures_lignes_c
JOIN activite.p_factures ON p_factures.no_facture = p_factures_lignes_c.no_facture
JOIN w_apply_dotation ON
p_factures_lignes_c.rubrique_facturation_id = ANY(w_apply_dotation.rubrique_facturation_id_array) AND
date_part('year',p_factures_lignes_c.date_fin) = w_apply_dotation.annee
GROUP BY 1
;
UPDATE activite.p_factures_reference SET
montant_facture = w_apply_dotation_factures.montant_facture_c + p_factures_reference.montant_facture_h,
montant_facture_c = w_apply_dotation_factures.montant_facture_c,
montant_facture_1 = w_apply_dotation_factures.montant_facture_1_c + p_factures_reference.montant_facture_1_h,
montant_facture_1_c = w_apply_dotation_factures.montant_facture_1_c,
montant_facture_2 = w_apply_dotation_factures.montant_facture_2_c + w_apply_dotation_factures.montant_facture_22_c + p_factures_reference.montant_facture_2_h,
montant_facture_2_c = w_apply_dotation_factures.montant_facture_2_c + w_apply_dotation_factures.montant_facture_22_c,
montant_encours = w_apply_dotation_factures.montant_encours_c + p_factures_reference.montant_encours_h,
montant_encours_c = w_apply_dotation_factures.montant_encours_c,
montant_comptabilise_budget_global_c = w_apply_dotation_factures.montant_facture_1_c
FROM w_apply_dotation_factures
WHERE p_factures_reference.no_facture_reference = w_apply_dotation_factures.no_facture_reference
;
UPDATE activite.p_factures_lignes_c
SET prix_unitaire = montant_facture / nb_rubrique
WHERE rubrique_facturation_id <> 0 AND
rubrique_facturation_id IN (SELECT to_rubrique_facturation_id FROM activite.t_service_rubrique_dotation WHERE to_rubrique_facturation_id <> 0)
;
RETURN 'OK';
END;