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.
 
 

231 lines
8.5 KiB

return: text
lang: plpgsql
src: |
DECLARE
result TEXT;
BEGIN
-- remplacer Chiffre d'affaires fil de l'eau PMSI par celui d'activité
INSERT INTO activite.t_divers (code, texte, valeur, description)
SELECT
'AJUSTFILDELEAU',
'Ajustement données fil de l''eau PMSI',
'0',
'0=Non, 1=Oui '
WHERE 'AJUSTFILDELEAU' NOT IN (SELECT code FROM activite.t_divers);
IF NOT EXISTS (SELECT *
FROM activite.t_divers
WHERE t_divers.code = 'AJUSTFILDELEAU' AND
t_divers.valeur = '1'
LIMIT 1) THEN
return 'Non paramétré';
END IF;
IF NOT EXISTS (SELECT * FROM pg_tables WHERE schemaname = 'pmsi' AND tablename = 'p_rss') THEN
return 'Pas de PMSI';
END IF;
-- CA à générer d'après lignes de factures ou d'encours
DROP TABLE IF EXISTS w_encours_pmsi_rsf_detail;
CREATE TEMP TABLE w_encours_pmsi_rsf_detail AS
SELECT
p_rss.finess AS finess,
p_rss.oid AS rss_id,
p_rss.no_rss AS no_rss,
'' AS nature,
'' AS mt,
'' AS dmt,
MIN(p_factures_lignes_c.date_debut) AS date_debut,
MAX(p_factures_lignes_c.date_fin) AS date_fin,
SUM(p_factures_lignes_c.nb_prestation) AS nombre,
p_factures_lignes_c.coefficient AS coefficient,
p_factures_lignes_c.prix_unitaire AS prix_unitaire,
SUM(montant_facture+montant_encours) AS base_remboursement,
taux_1 AS taux_remboursement,
SUM(montant_facture+montant_encours) AS sejour_facture,
SUM(montant_facture_1+montant_encours_1) AS sejour_remboursable,
0::numeric AS compteur,
'' AS ligne_t2a,
'' AS pec_fj,
p_factures_lignes_c.coefficient_mco,
0 AS sejour_remboursable_2,
p_rss.ghs_id,
0 AS sejour_rembourse_noemie,
'' AS nature_noemie,
t_prestations_pmsi.oid AS prestation_id,
'B' AS type,
0 AS coefficient_geo,
'1'::text AS est_ligne_rss,
'0'::text AS est_ligne_rum,
t_prestations.code AS prestation_code,
CASE WHEN t_prestations.code IN ('D09','D13') THEN p_factures_lignes_c.date_debut ELSE NULL END AS date_debut_seance,
CASE WHEN t_prestations.code IN ('D09','D13') THEN p_factures_lignes_c.date_fin ELSE NULL END AS date_fin_seance
FROM activite.p_sejours
JOIN activite.t_lieux ON t_lieux.oid = lieu_sortie_id
JOIN activite.t_services_facturation ON service_facturation_id = t_services_facturation.oid
JOIN activite.p_sejour_pmsi ON p_sejours.oid = p_sejour_pmsi.sejour_id
JOIN pmsi.p_rss ON p_sejour_pmsi.rss_id = p_rss.oid
JOIN activite.p_factures ON p_sejours.no_sejour = p_factures.no_sejour
JOIN activite.p_factures_lignes_c ON p_factures.no_facture = p_factures_lignes_c.no_facture
JOIN activite.t_prestations ON prestation_id = t_prestations.oid
JOIN pmsi.t_prestations t_prestations_pmsi ON t_prestations_pmsi.code = t_prestations.code
WHERE p_sejours.type_sejour IN ('1','2','5') AND
p_sejours.code_sorti = '1' AND
p_sejours.date_sortie >= date(date_trunc('year',now()-interval '18 month')) AND
(
t_services_facturation.type_t2a = '1' OR
p_sejours.ghm_id > 0
) AND
p_rss.en_cours = '1' AND
(
montant_facture_1 <> 0 OR
montant_encours_1 <> 0
) AND
p_factures_lignes_c.date_fin BETWEEN p_rss.date_entree AND p_rss.date_sortie
GROUP BY 1,2,3,10,11,13,19,21,24,29,30,31
HAVING SUM(montant_facture+montant_encours) > 0
;
DROP TABLE IF EXISTS w_encours_pmsi_rss;
CREATE TEMP TABLE w_encours_pmsi_rss AS
SELECT rss_id
FROM w_encours_pmsi_rsf_detail
GROUP BY 1
;
ANALYSE w_encours_pmsi_rss
;
-- Suppression du CA déjà généré
DELETE FROM pmsi.p_rsf_detail
WHERE p_rsf_detail.rss_id IN (SELECT w_encours_pmsi_rss.rss_id FROM w_encours_pmsi_rss)
;
-- Ajout des nouvelles lignes
INSERT INTO pmsi.p_rsf_detail(
finess,
rss_id,
no_rss,
nature,
mt,
dmt,
date_debut,
date_fin,
nombre,
coefficient,
prix_unitaire,
base_remboursement,
taux_remboursement,
sejour_facture,
sejour_remboursable,
compteur,
ligne_t2a,
pec_fj,
coefficient_mco,
sejour_remboursable_2,
ghs_id,
sejour_rembourse_noemie,
nature_noemie,
prestation_id,
type,
coefficient_geo,
est_ligne_rss,
est_ligne_rum
)
SELECT
finess,
rss_id,
no_rss,
nature,
mt,
dmt,
date_debut,
date_fin,
nombre,
coefficient,
prix_unitaire,
base_remboursement,
taux_remboursement,
sejour_facture,
sejour_remboursable,
compteur,
ligne_t2a,
pec_fj,
coefficient_mco,
sejour_remboursable_2,
ghs_id,
sejour_rembourse_noemie,
nature_noemie,
prestation_id,
type,
coefficient_geo,
est_ligne_rss,
est_ligne_rum
FROM w_encours_pmsi_rsf_detail
;
-- Réplication cumuls
UPDATE pmsi.p_rsf_total SET
base_remboursement = COALESCE(subview.base_remboursement,0),
t2a_facture = COALESCE(subview.t2a_facture,0),
dmi_facture = COALESCE(subview.dmi_facture,0),
phc_facture = COALESCE(subview.phc_facture,0),
forfait_facture = COALESCE(subview.forfait_facture,0),
nb_exh = COALESCE(subview.nb_exh,0),
ca_exh = COALESCE(subview.ca_exh,0),
nb_exb = COALESCE(subview.nb_exb,0),
ca_exb = COALESCE(subview.ca_exb,0),
nb_ghs = COALESCE(subview.nb_ghs,0),
ca_ghs = COALESCE(subview.ca_ghs,0),
nb_ghsmin = COALESCE(subview.nb_ghsmin,0)
FROM pmsi.p_rss
LEFT JOIN (
SELECT rss_id,
SUM(p_rsf_detail.base_remboursement) as base_remboursement,
SUM(CASE WHEN t_prestations.section_code[9] LIKE 'S1%' THEN p_rsf_detail.base_remboursement ELSE 0 END) as t2a_facture,
SUM(CASE WHEN t_prestations.section_code[9] LIKE 'S2%' THEN p_rsf_detail.base_remboursement ELSE 0 END) as dmi_facture,
SUM(CASE WHEN t_prestations.section_code[9] LIKE 'S3%' THEN p_rsf_detail.base_remboursement ELSE 0 END) as phc_facture,
SUM(CASE WHEN t_prestations.code = 'EXH' THEN p_rsf_detail.nombre ELSE 0 END) as nb_exh,
SUM(CASE WHEN t_prestations.code = 'EXH' THEN p_rsf_detail.base_remboursement ELSE 0 END) as ca_exh,
SUM(CASE WHEN t_prestations.code = 'GHS' AND coefficient > 0 AND coefficient < 1 AND t_ghs.code NOT IN (9606,9616) THEN p_rsf_detail.nombre ELSE 0 END) as nb_exb,
SUM(CASE WHEN t_prestations.code = 'GHS' AND coefficient > 0 AND coefficient < 1 AND t_ghs.code NOT IN (9606,9616) THEN p_rsf_detail.base_remboursement ELSE 0 END) as ca_exb,
SUM(CASE WHEN t_prestations.code = 'GHS' AND coefficient > 0 AND coefficient < 1 AND t_ghs.code IN (9606,9616) THEN p_rsf_detail.nombre ELSE 0 END) as nb_ghsmin,
SUM(CASE WHEN t_prestations.code = 'GHS' THEN p_rsf_detail.nombre ELSE 0 END) as nb_ghs,
SUM(CASE WHEN t_prestations.code = 'GHS' THEN p_rsf_detail.base_remboursement ELSE 0 END) as ca_ghs,
SUM(CASE WHEN t_prestations.section_code[9] LIKE 'S13%' THEN p_rsf_detail.base_remboursement ELSE 0 END) as forfait_facture
FROM pmsi.p_rsf_detail
JOIN pmsi.t_prestations ON p_rsf_detail.prestation_id = t_prestations.oid JOIN pmsi.t_ghs ON t_ghs.oid = p_rsf_detail.ghs_id
WHERE p_rsf_detail.type = 'B' AND p_rsf_detail.est_ligne_rss = '1' AND
p_rsf_detail.rss_id IN (SELECT w_encours_pmsi_rss.rss_id FROM w_encours_pmsi_rss)
GROUP BY rss_id) subview ON p_rss.oid = subview.rss_id
WHERE p_rsf_total.rss_id = p_rss.oid AND
p_rsf_total.rss_id IN (SELECT w_encours_pmsi_rss.rss_id FROM w_encours_pmsi_rss);
-- total rss
UPDATE pmsi.p_rss
SET base_remboursement = p_rsf_total.base_remboursement,
sejour_facture = p_rsf_total.sejour_facture,
honoraires_factures = p_rsf_total.honoraires_factures,
t2a_facture = p_rsf_total.t2a_facture,
dmi_facture = p_rsf_total.dmi_facture,
phc_facture = p_rsf_total.phc_facture,
ca_ghs_theorique = p_rsf_total.ca_ghs_theorique,
nb_ghs = p_rsf_total.nb_ghs,
ca_ghs = p_rsf_total.ca_ghs,
nb_exb = p_rsf_total.nb_exb,
ca_exb = p_rsf_total.ca_exb,
nb_exh = p_rsf_total.nb_exh,
ca_exh = p_rsf_total.ca_exh,
nb_ghsmin = p_rsf_total.nb_ghsmin,
forfait_facture = p_rsf_total.forfait_facture
FROM pmsi.p_rsf_total
WHERE p_rss.oid = p_rsf_total.rss_id AND
p_rss.oid IN (SELECT w_encours_pmsi_rss.rss_id FROM w_encours_pmsi_rss)
;
RETURN 'OK';
END;