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.
 
 

396 lines
18 KiB

<?xml version="1.0" encoding="ISO-8859-1"?>
<ROOT>
<NODE name="EXEC" label="CALCUL DES ENCOURS">
<NODE label="Calcul encours">
<sqlcmd><![CDATA[
SELECT activite.calcul_encours(NULL,'');
SELECT activite.cti_ajust_encours();
]]></sqlcmd>
</NODE>
<NODE label="Compléments lignes générées">
<sqlcmd><![CDATA[
-- Génération lignes fictive clinique pour facturation uniquement honoraires
SELECT activite.cti_gen_0ets();
-- Compte produit
-- Forcage depuis parametrage
UPDATE activite.p_factures_lignes_c
SET compte_produit_id =
CASE
WHEN est_compte_force = '1' THEN t_service_rubrique.compte_id
WHEN p_factures_lignes_c.compte_produit_id = 0 THEN t_service_rubrique.compte_id
ELSE p_factures_lignes_c.compte_produit_id END
FROM activite.t_lieux,
activite.t_service_rubrique
WHERE lieu_id = t_lieux.oid AND
t_service_rubrique.service_facturation_id = t_lieux.service_facturation_id AND
t_service_rubrique.rubrique_facturation_id = p_factures_lignes_c.rubrique_facturation_id AND
t_service_rubrique.compte_id <> 0 AND
p_factures_lignes_c.compte_produit_id IS DISTINCT FROM
CASE
WHEN est_compte_force = '1' THEN t_service_rubrique.compte_id
WHEN p_factures_lignes_c.compte_produit_id = 0 THEN t_service_rubrique.compte_id
ELSE p_factures_lignes_c.compte_produit_id END
;
-- Déduction depuis historique service rubrique
DROP TABLE IF EXISTS w_factures_lignes_c_compte_serrub;
CREATE TEMP TABLE w_factures_lignes_c_compte_serrub AS
SELECT rubrique_facturation_id, service_facturation_id, (MAX(Array[date_vente::text || to_char(nb,'FM000000000000'), compte_produit_id::text]))[2]::bigint AS compte_produit_id
FROM
(
SELECT rubrique_facturation_id, service_facturation_id, date(date_trunc('month',date_vente)) AS date_vente, compte_produit_id, count(*) AS nb
FROM activite.p_factures_lignes_c
JOIN activite.p_factures ON p_factures_lignes_c.no_facture = p_factures.no_facture
JOIN activite.t_lieux ON p_factures_lignes_c.lieu_id = t_lieux.oid
WHERE compte_produit_id <> 0 AND date_vente < '20991231'
GROUP BY 1,2,3,4
) subview
GROUP BY 1,2;
CREATE INDEX w_factures_lignes_c_compte_serrub_i1
ON w_factures_lignes_c_compte_serrub
USING btree
(rubrique_facturation_id);
UPDATE activite.p_factures_lignes_c
SET compte_produit_id = w_factures_lignes_c_compte_serrub.compte_produit_id
FROM w_factures_lignes_c_compte_serrub,
activite.t_lieux
WHERE p_factures_lignes_c.compte_produit_id = 0 AND
p_factures_lignes_c.lieu_id = t_lieux.oid AND
p_factures_lignes_c.rubrique_facturation_id = w_factures_lignes_c_compte_serrub.rubrique_facturation_id AND
t_lieux.service_facturation_id = w_factures_lignes_c_compte_serrub.service_facturation_id;
-- Déduction depuis historique service prestation
DROP TABLE IF EXISTS w_factures_lignes_c_compte_serpre;
CREATE TEMP TABLE w_factures_lignes_c_compte_serpre AS
SELECT prestation_id, service_facturation_id, (MAX(Array[date_vente::text || to_char(nb,'FM000000000000'), compte_produit_id::text]))[2]::bigint AS compte_produit_id
FROM
(
SELECT prestation_id, service_facturation_id, date(date_trunc('month',date_vente)) AS date_vente, compte_produit_id, count(*) AS nb
FROM activite.p_factures_lignes_c
JOIN activite.p_factures ON p_factures_lignes_c.no_facture = p_factures.no_facture
JOIN activite.t_lieux ON p_factures_lignes_c.lieu_id = t_lieux.oid
WHERE compte_produit_id <> 0 AND date_vente < '20991231'
GROUP BY 1,2,3,4
) subview
GROUP BY 1,2;
CREATE INDEX w_factures_lignes_c_compte_serpre_i1
ON w_factures_lignes_c_compte_serpre
USING btree
(prestation_id);
UPDATE activite.p_factures_lignes_c
SET compte_produit_id = w_factures_lignes_c_compte_serpre.compte_produit_id
FROM w_factures_lignes_c_compte_serpre,
activite.t_lieux
WHERE p_factures_lignes_c.compte_produit_id = 0 AND
p_factures_lignes_c.lieu_id = t_lieux.oid AND
p_factures_lignes_c.prestation_id = w_factures_lignes_c_compte_serpre.prestation_id AND
t_lieux.service_facturation_id = w_factures_lignes_c_compte_serpre.service_facturation_id;
-- Déduction depuis historique rubrique uniquement
DROP TABLE IF EXISTS w_factures_lignes_c_compte_rub;
CREATE TEMP TABLE w_factures_lignes_c_compte_rub AS
SELECT rubrique_facturation_id, (MAX(Array[date_vente::text || to_char(nb,'FM000000000000'), compte_produit_id::text]))[2]::bigint AS compte_produit_id
FROM
(
SELECT rubrique_facturation_id, date(date_trunc('month',date_vente)) AS date_vente, compte_produit_id, count(*) AS nb
FROM activite.p_factures_lignes_c
JOIN activite.p_factures ON p_factures_lignes_c.no_facture = p_factures.no_facture
WHERE compte_produit_id <> 0 AND date_vente < '20991231'
GROUP BY 1,2,3
) subview
GROUP BY 1;
CREATE INDEX w_factures_lignes_c_compte_rub_i1
ON w_factures_lignes_c_compte_rub
USING btree
(rubrique_facturation_id);
UPDATE activite.p_factures_lignes_c
SET compte_produit_id = w_factures_lignes_c_compte_rub.compte_produit_id
FROM w_factures_lignes_c_compte_rub
WHERE p_factures_lignes_c.compte_produit_id = 0 AND
p_factures_lignes_c.rubrique_facturation_id = w_factures_lignes_c_compte_rub.rubrique_facturation_id;
-- Forcage depuis parametrage
UPDATE activite.p_factures_encours_lignes_c
SET compte_produit_id =
CASE
WHEN est_compte_force = '1' THEN t_service_rubrique.compte_id
WHEN p_factures_encours_lignes_c.compte_produit_id = 0 THEN t_service_rubrique.compte_id
ELSE p_factures_encours_lignes_c.compte_produit_id END
FROM activite.t_lieux,
activite.t_service_rubrique
WHERE lieu_id = t_lieux.oid AND
t_service_rubrique.service_facturation_id = t_lieux.service_facturation_id AND
t_service_rubrique.rubrique_facturation_id = p_factures_encours_lignes_c.rubrique_facturation_id AND
t_service_rubrique.compte_id <> 0 AND
p_factures_encours_lignes_c.compte_produit_id IS DISTINCT FROM
CASE
WHEN est_compte_force = '1' THEN t_service_rubrique.compte_id
WHEN p_factures_encours_lignes_c.compte_produit_id = 0 THEN t_service_rubrique.compte_id
ELSE p_factures_encours_lignes_c.compte_produit_id END
;
-- Déduction depuis historiques service rubrique
UPDATE activite.p_factures_encours_lignes_c
SET compte_produit_id = w_factures_lignes_c_compte_serrub.compte_produit_id
FROM w_factures_lignes_c_compte_serrub,
activite.t_lieux
WHERE (p_factures_encours_lignes_c.compte_produit_id = 0 OR p_factures_encours_lignes_c.compte_produit_id IS NULL) AND
p_factures_encours_lignes_c.lieu_id = t_lieux.oid AND
p_factures_encours_lignes_c.rubrique_facturation_id = w_factures_lignes_c_compte_serrub.rubrique_facturation_id AND
t_lieux.service_facturation_id = w_factures_lignes_c_compte_serrub.service_facturation_id;
-- Déduction depuis historiques service prestation
UPDATE activite.p_factures_encours_lignes_c
SET compte_produit_id = w_factures_lignes_c_compte_serpre.compte_produit_id
FROM w_factures_lignes_c_compte_serpre,
activite.t_lieux
WHERE p_factures_encours_lignes_c.compte_produit_id = 0 AND
p_factures_encours_lignes_c.lieu_id = t_lieux.oid AND
p_factures_encours_lignes_c.prestation_id = w_factures_lignes_c_compte_serpre.prestation_id AND
t_lieux.service_facturation_id = w_factures_lignes_c_compte_serpre.service_facturation_id;
-- Déduction depuis historiques rubrique uniquement
UPDATE activite.p_factures_encours_lignes_c
SET compte_produit_id = w_factures_lignes_c_compte_rub.compte_produit_id
FROM w_factures_lignes_c_compte_rub
WHERE (p_factures_encours_lignes_c.compte_produit_id = 0 OR p_factures_encours_lignes_c.compte_produit_id IS NULL) AND
p_factures_encours_lignes_c.rubrique_facturation_id = w_factures_lignes_c_compte_rub.rubrique_facturation_id;
-- Maintenance rubrique_facturation CTI
SELECT activite.cti_reorganize_rubrique_facture_c('activite.p_factures_lignes_c');
SELECT activite.cti_reorganize_rubrique_facture_c('activite.p_factures_encours_lignes_c');
-- Regroupement des lignes de CP (cas de rubriques facturées deux fois sur même date pour pb tarif patient/mutuelle
DROP TABLE IF EXISTS w_cp_double;
CREATE TEMP TABLE w_cp_double AS
SELECT
no_facture, date_debut, date_fin, prestation_id, rubrique_facturation_id, nb_rubrique, nb_prestation, coefficient,
SUM(prix_unitaire) AS prix_unitaire,
round(base.cti_division(SUM(montant_facture_1),SUM(montant_facture))*100.00,0) AS taux_1,
round(base.cti_division(SUM(montant_facture_2),SUM(montant_facture))*100.00,0) AS taux_2,
round(base.cti_division(SUM(montant_facture_22),SUM(montant_facture))*100.00,0) AS taux_22,
round(base.cti_division(SUM(montant_facture_0),SUM(montant_facture))*100.00,0) AS taux_0,
SUM(montant_facture) AS montant_facture,
SUM(montant_facture_0) AS montant_facture_0,
SUM(montant_facture_1) AS montant_facture_1,
SUM(montant_facture_2) AS montant_facture_2,
SUM(montant_facture_22) AS montant_facture_22,
SUM(montant_comptabilise) AS montant_comptabilise,
SUM(montant_comptabilise_0) AS montant_comptabilise_0,
SUM(montant_comptabilise_1) AS montant_comptabilise_1,
SUM(montant_comptabilise_2) AS montant_comptabilise_2,
SUM(montant_comptabilise_22) AS montant_comptabilise_22,
SUM(montant_encours) AS montant_encours,
SUM(montant_encours_0) AS montant_encours_0,
SUM(montant_encours_1) AS montant_encours_1,
SUM(montant_encours_2) AS montant_encours_2,
SUM(montant_encours_22) AS montant_encours_22,
MIN(p_factures_lignes_c.CTID) AS keepCTID
FROM activite.p_factures_lignes_c
WHERE rubrique_facturation_id IN (SELECT to_id FROM activite.v_listes_3 WHERE liste_code = 'CTI_SHO_R') AND
montant_facture <> 0
GROUP BY 1,2,3,4,5,6,7,8
HAVING count(*) > 1;
INSERT INTO w_cp_double
SELECT
no_facture, date_debut, date_fin, MAX(prestation_id) AS prestation_id, rubrique_facturation_id, 1 AS nb_rubrique, 1 AS nb_prestation, 1 AS coefficient,
SUM(montant_encours) AS prix_unitaire,
round(base.cti_division(SUM(montant_facture_1),SUM(montant_facture))*100.00,0) AS taux_1,
round(base.cti_division(SUM(montant_facture_2),SUM(montant_facture))*100.00,0) AS taux_2,
round(base.cti_division(SUM(montant_facture_22),SUM(montant_facture))*100.00,0) AS taux_22,
round(base.cti_division(SUM(montant_facture_0),SUM(montant_facture))*100.00,0) AS taux_0,
SUM(montant_facture) AS montant_facture,
SUM(montant_facture_0) AS montant_facture_0,
SUM(montant_facture_1) AS montant_facture_1,
SUM(montant_facture_2) AS montant_facture_2,
SUM(montant_facture_22) AS montant_facture_22,
SUM(montant_comptabilise) AS montant_comptabilise,
SUM(montant_comptabilise_0) AS montant_comptabilise_0,
SUM(montant_comptabilise_1) AS montant_comptabilise_1,
SUM(montant_comptabilise_2) AS montant_comptabilise_2,
SUM(montant_comptabilise_22) AS montant_comptabilise_22,
SUM(montant_encours) AS montant_encours,
SUM(montant_encours_0) AS montant_encours_0,
SUM(montant_encours_1) AS montant_encours_1,
SUM(montant_encours_2) AS montant_encours_2,
SUM(montant_encours_22) AS montant_encours_22,
MIN(p_factures_lignes_c.CTID) AS keepCTID
FROM activite.p_factures_lignes_c
WHERE rubrique_facturation_id IN (SELECT to_id FROM activite.v_listes_3 WHERE liste_code = 'CTI_SHO_R') AND
montant_encours <> 0
GROUP BY 1,2,3,5,6,7
HAVING count(*) > 1;
UPDATE w_cp_double
SET prestation_id = subview.prestation_id
FROM
(
SELECT rubrique_facturation_id, (MAX(ARRAY[nb,prestation_id]))[2] AS prestation_id
FROM
(
SELECT rubrique_facturation_id, prestation_id, count(*) AS nb
FROM w_cp_double
GROUP BY 1,2) subview
GROUP BY 1
) subview
WHERE w_cp_double.rubrique_facturation_id = subview.rubrique_facturation_id AND
w_cp_double.prestation_id <> subview.prestation_id;
CREATE INDEX w_cp_double_i1
ON w_cp_double
USING btree
(no_facture);
DELETE FROM activite.p_factures_lignes_c
USING w_cp_double
WHERE p_factures_lignes_c.no_facture = w_cp_double.no_facture AND
p_factures_lignes_c.date_debut = w_cp_double.date_debut AND
p_factures_lignes_c.date_fin = w_cp_double.date_fin AND
(p_factures_lignes_c.prestation_id = w_cp_double.prestation_id OR w_cp_double.montant_encours <> 0) AND
p_factures_lignes_c.rubrique_facturation_id = w_cp_double.rubrique_facturation_id AND
(p_factures_lignes_c.nb_rubrique = w_cp_double.nb_rubrique OR w_cp_double.montant_encours <> 0) AND
(p_factures_lignes_c.nb_prestation = w_cp_double.nb_prestation OR w_cp_double.montant_encours <> 0) AND
(p_factures_lignes_c.coefficient = w_cp_double.coefficient OR w_cp_double.montant_encours <> 0) AND
p_factures_lignes_c.CTID <> keepCTID;
UPDATE activite.p_factures_lignes_c SET
prestation_id = w_cp_double.prestation_id,
nb_rubrique = w_cp_double.nb_rubrique,
nb_prestation = w_cp_double.nb_prestation,
coefficient = w_cp_double.coefficient,
prix_unitaire = w_cp_double.prix_unitaire,
taux_0 = w_cp_double.taux_0,
taux_1 = w_cp_double.taux_1,
taux_2 = w_cp_double.taux_2,
taux_22 = w_cp_double.taux_22,
montant_facture = w_cp_double.montant_facture,
montant_facture_0 = w_cp_double.montant_facture_0,
montant_facture_1 = w_cp_double.montant_facture_1,
montant_facture_2 = w_cp_double.montant_facture_2,
montant_facture_22 = w_cp_double.montant_facture_22,
montant_comptabilise = w_cp_double.montant_comptabilise,
montant_comptabilise_0 = w_cp_double.montant_comptabilise_0,
montant_comptabilise_1 = w_cp_double.montant_comptabilise_1,
montant_comptabilise_2 = w_cp_double.montant_comptabilise_2,
montant_comptabilise_22 = w_cp_double.montant_comptabilise_22,
montant_encours = w_cp_double.montant_encours,
montant_encours_0 = w_cp_double.montant_encours_0,
montant_encours_1 = w_cp_double.montant_encours_1,
montant_encours_2 = w_cp_double.montant_encours_2,
montant_encours_22 = w_cp_double.montant_encours_22
FROM w_cp_double
WHERE p_factures_lignes_c.no_facture = w_cp_double.no_facture AND
p_factures_lignes_c.date_debut = w_cp_double.date_debut AND
p_factures_lignes_c.date_fin = w_cp_double.date_fin AND
(p_factures_lignes_c.prestation_id = w_cp_double.prestation_id OR w_cp_double.montant_encours <> 0) AND
p_factures_lignes_c.rubrique_facturation_id = w_cp_double.rubrique_facturation_id AND
(p_factures_lignes_c.nb_rubrique = w_cp_double.nb_rubrique OR w_cp_double.montant_encours <> 0) AND
(p_factures_lignes_c.nb_prestation = w_cp_double.nb_prestation OR w_cp_double.montant_encours <> 0) AND
(p_factures_lignes_c.coefficient = w_cp_double.coefficient OR w_cp_double.montant_encours <> 0);
-- Reconstitution factures références
DROP TABLE IF EXISTS w_factures_reference;
CREATE TEMP TABLE w_factures_reference AS
SELECT
no_facture_reference,
SUM(p_factures.montant_encours_c + p_factures.montant_encours_h) AS montant_encours,
SUM(p_factures.montant_encours_c) AS montant_encours_c,
SUM(p_factures.montant_encours_h) AS montant_encours_h,
SUM(p_factures.montant_encours_0_c + p_factures.montant_encours_0_h) AS montant_encours_0,
SUM(p_factures.montant_encours_0_c) AS montant_encours_0_c,
SUM(p_factures.montant_encours_0_h) AS montant_encours_0_h,
SUM(p_factures.montant_encours_1_c + p_factures.montant_encours_1_h) AS montant_encours_1,
SUM(p_factures.montant_encours_1_c) AS montant_encours_1_c,
SUM(p_factures.montant_encours_1_h) AS montant_encours_1_h,
SUM(p_factures.montant_encours_2_c + p_factures.montant_encours_2_h + p_factures.montant_encours_22_c + p_factures.montant_encours_22_h) AS montant_encours_2,
SUM(p_factures.montant_encours_2_c + p_factures.montant_encours_22_c) AS montant_encours_2_c,
SUM(p_factures.montant_encours_2_h + p_factures.montant_encours_22_h) AS montant_encours_2_h
FROM activite.p_sejours
JOIN activite.p_factures ON p_factures.no_sejour = p_sejours.no_sejour
JOIN activite.t_lieux ON p_sejours.lieu_sortie_id = t_lieux.oid
JOIN activite.t_services_facturation ON service_facturation_id = t_services_facturation.oid
WHERE t_services_facturation.est_sans_facturation IS DISTINCT FROM '1' AND
code_prevu <> 1
GROUP BY 1
;
UPDATE activite.p_factures_reference SET
montant_encours = w_factures_reference.montant_encours,
montant_encours_c = w_factures_reference.montant_encours_c,
montant_encours_h = w_factures_reference.montant_encours_h,
montant_encours_0 = w_factures_reference.montant_encours_0,
montant_encours_0_c = w_factures_reference.montant_encours_0_c,
montant_encours_0_h = w_factures_reference.montant_encours_0_h,
montant_encours_1 = w_factures_reference.montant_encours_1,
montant_encours_1_c = w_factures_reference.montant_encours_1_c,
montant_encours_1_h = w_factures_reference.montant_encours_1_h,
montant_encours_2 = w_factures_reference.montant_encours_2,
montant_encours_2_c = w_factures_reference.montant_encours_2_c,
montant_encours_2_h = w_factures_reference.montant_encours_2_h
FROM w_factures_reference
WHERE p_factures_reference.no_facture_reference = w_factures_reference.no_facture_reference AND
p_factures_reference.montant_encours <> w_factures_reference.montant_encours
;
]]></sqlcmd>
</NODE>
<NODE label="Réorganisation tables">
<sqlcmd><![CDATA[
VACUUM ANALYSE activite.p_factures;
VACUUM ANALYSE activite.p_factures_encours;
VACUUM ANALYSE activite.p_factures_encours_lignes_c;
VACUUM ANALYSE activite.p_factures_lignes_c;
VACUUM ANALYSE activite.p_factures_reference;
VACUUM ANALYSE activite.p_facture_ligne_valorise_c;
]]></sqlcmd>
</NODE>
</NODE>
</ROOT>