pour déploiement auto v2 via gitlab
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.
 
 

457 lines
20 KiB

return: text
lang: plpgsql
parameters:
p0:
type: bigint
name: i_enquete_id
default: "0"
src: |
DECLARE
result TEXT;
BEGIN
DROP TABLE IF EXISTS w_fiche5_enquete;
CREATE TEMP TABLE w_fiche5_enquete AS
SELECT *
FROM pmsi.t_fiche5_enquete
WHERE i_enquete_id = 0 OR
oid = i_enquete_id
;
UPDATE w_fiche5_enquete
SET data = replace(data,E'\t','|')
;
UPDATE w_fiche5_enquete
SET data = replace(data,E'\r'||E'\n','[[')
;
UPDATE w_fiche5_enquete
SET data = replace(data,E'\n'||E'\r','[[')
;
UPDATE w_fiche5_enquete
SET data = replace(data,E'\n','[[')
;
UPDATE w_fiche5_enquete
SET data = replace(data,E'\r','[[')
;
DROP TABLE IF EXISTS w_fiche5_rss;
CREATE TEMP TABLE w_fiche5_rss AS
SELECT enquete_id,
base.cti_to_number(COALESCE(import_cellule_array[1],'0')) AS no_ogc,
CASE WHEN import_cellule_array[3] IS NOT NULL AND import_cellule_array[4] IS NOT NULL AND import_cellule_array[5] IS NOT NULL THEN
base.cti_to_number(COALESCE(substr(import_cellule_array[10],28,20),'0'))
ELSE
base.cti_to_number(COALESCE(import_cellule_array[2],'0'))
END
AS no_rss,
import_cellule_array[4] AS champ_code,
import_cellule_array[5] AS champ_texte,
0::bigint AS champ_id,
substr(import_cellule_array[10],28,20),
0::bigint AS fiche5_rss_id
FROM
(
SELECT enquete_id, import_ligne, string_to_array(import_ligne,'|') AS import_cellule_array
FROM
(
SELECT enquete_id, unnest(data_array) AS import_ligne
FROM
(
SELECT
oid AS enquete_id, string_to_array(data,'[[') AS data_array
FROM w_fiche5_enquete
) subview
) subview
) subview
;
UPDATE w_fiche5_rss
SET fiche5_rss_id = p_fiche5_rss.oid
FROM pmsi.p_fiche5_rss
WHERE p_fiche5_rss.enquete_id = w_fiche5_rss.enquete_id AND
p_fiche5_rss.no_ogc = w_fiche5_rss.no_ogc
;
DELETE FROM pmsi.p_fiche5_rss
WHERE enquete_id IN (SELECT enquete_id FROM w_fiche5_rss) AND
oid NOT IN (SELECT fiche5_rss_id FROM w_fiche5_rss)
;
UPDATE pmsi.p_fiche5_rss
SET no_rss = w_fiche5_rss.no_rss
FROM w_fiche5_rss
WHERE w_fiche5_rss.fiche5_rss_id = p_fiche5_rss.oid AND
p_fiche5_rss.no_rss IS DISTINCT FROM w_fiche5_rss.no_rss
;
INSERT INTO pmsi.t_fiche5_champ(code, enquete_id, texte)
SELECT champ_code, enquete_id, MAX(replace(champ_texte,'?','é')) AS champ_texte
FROM w_fiche5_rss
WHERE champ_code IS NOT NULL AND
(enquete_id::text||'|'||champ_code) NOT IN (SELECT (enquete_id::text||'|'||code) FROM pmsi.t_fiche5_champ)
GROUP BY 1,2
;
UPDATE w_fiche5_rss
SET champ_id = t_fiche5_champ.oid
FROM pmsi.t_fiche5_champ
WHERE w_fiche5_rss.enquete_id = t_fiche5_champ.enquete_id AND
w_fiche5_rss.champ_code = t_fiche5_champ.code
;
INSERT INTO pmsi.p_fiche5_rss (enquete_id, no_ogc, no_rss, champ_id)
SELECT w_fiche5_rss.enquete_id, w_fiche5_rss.no_ogc, w_fiche5_rss.no_rss, MAX(w_fiche5_rss.champ_id)
FROM w_fiche5_rss
WHERE no_ogc <> 0 AND no_rss <> 0 AND fiche5_rss_id = 0
GROUP BY 1,2,3
;
UPDATE pmsi.p_fiche5_rss
SET champ_id = w_fiche5_rss.champ_id
FROM w_fiche5_rss
WHERE fiche5_rss_id = p_fiche5_rss.oid
;
ANALYSE w_fiche5_rss
;
UPDATE pmsi.p_fiche5_rss SET
rss_id = p_rss.oid,
no_sejour_administratif = trim(p_rss.no_sejour_administratif),
no_patient = CASE WHEN p_patients.no_patient > 0 THEN p_patients.no_patient ELSE 0 END,
date_naissance = p_rss.date_naissance,
date_entree = p_rss.date_entree,
date_sortie = p_rss.date_sortie,
mode_sortie = p_rss.mode_sortie,
duree_sejour = p_rss.duree_sejour,
facture_dp_id = p_rss.diagnostic_principal_id,
facture_dp_code = COALESCE(t_diagnostics.code,''),
facture_ghs_id = p_rss.ghs_id,
facture_ghs_code = COALESCE(to_char(t_ghs.code,'FM0000'),''),
facture_ghm_id = p_rss.ghm_id,
facture_ghm_code = COALESCE(t_ghm.code,'')
FROM pmsi.t_fiche5_enquete
JOIN pmsi.p_rss ON
p_rss.ghm_id > 0 AND
p_rss.en_cours = '0' AND
date_part('year',p_rss.date_sortie) = t_fiche5_enquete.annee
LEFT JOIN pmsi.t_ghm ON p_rss.ghm_id = t_ghm.oid AND p_rss.ghm_id > 0
LEFT JOIN pmsi.t_ghs ON p_rss.ghs_id = t_ghs.oid AND p_rss.ghs_id > 0
LEFT JOIN pmsi.t_diagnostics ON p_rss.diagnostic_principal_id = t_diagnostics.oid AND p_rss.diagnostic_principal_id > 0
LEFT JOIN pmsi.p_patients ON p_rss.patient_id = p_patients.oid
WHERE p_fiche5_rss.no_rss = p_rss.no_rss
;
UPDATE pmsi.p_fiche5_rss SET
nom = p_identites.nom,
nom_naissance = p_identites.nom_naissance,
prenom = p_identites.prenom
FROM pmsi.p_identites
WHERE p_identites.rss_id = p_fiche5_rss.rss_id
;
UPDATE pmsi.p_fiche5_rss SET
matricule_assure = p_rsf_total.matricule_assure,
cle_matricule_assure = p_rsf_total.cle_matricule_assure,
no_facture = p_rsf_total.no_facture,
regime_code = COALESCE(t_grands_regimes.Code,''),
taux_remboursement = p_rsf_total.taux_remboursement
FROM pmsi.p_rsf_total
LEFT JOIN base.t_grands_regimes ON t_grands_regimes.oid = p_rsf_total.regime_id AND p_rsf_total.regime_id <> 0
WHERE p_rsf_total.rss_id = p_fiche5_rss.rss_id
;
UPDATE pmsi.p_fiche5_rss SET
taux_remboursement_vidhosp = p_vidhosp.taux_remboursement
FROM pmsi.p_vidhosp
WHERE p_vidhosp.rss_id = p_fiche5_rss.rss_id
;
UPDATE pmsi.p_fiche5_rss SET
caisse_gestionnaire_texte = subview.caisse_gestionnaire_texte,
caisse_gestionnaire_code = subview.caisse_gestionnaire_code
FROM
(
SELECT p_fiche5_rss.oid,
(MAX(Array[
CASE WHEN substr(t_tiers_payant.code,1,2) = p_fiche5_rss.regime_code THEN '1' ELSE '0' END || p_factures.date_facture::text,
COALESCE(t_tiers_payant.texte || ' (' || t_tiers_payant.code || ')','')
]))[2] AS caisse_gestionnaire_texte,
(MAX(Array[
CASE WHEN substr(t_tiers_payant.code,1,2) = p_fiche5_rss.regime_code THEN '1' ELSE '0' END || p_factures.date_facture::text,
CASE
WHEN substr(t_tiers_payant.code,1,2) = p_fiche5_rss.regime_code AND
length(t_tiers_payant.code) >= 9 AND
to_char(base.cti_to_number(substr(t_tiers_payant.code,3,3)),'FM000') = substr(t_tiers_payant.code,3,3) AND
to_char(base.cti_to_number(substr(t_tiers_payant.code,6,4)),'FM0000') = substr(t_tiers_payant.code,6,4) THEN
substr(t_tiers_payant.code,3,3)
WHEN substr(t_tiers_payant.code,1,2) = p_fiche5_rss.regime_code AND
length(t_tiers_payant.code) = 8 AND
to_char(base.cti_to_number(substr(t_tiers_payant.code,3,3)),'FM000') = substr(t_tiers_payant.code,3,3) AND
to_char(base.cti_to_number(substr(t_tiers_payant.code,6,3)),'FM000') = substr(t_tiers_payant.code,6,3) THEN
substr(t_tiers_payant.code,3,3)
WHEN substr(t_tiers_payant.code,1,2) = p_fiche5_rss.regime_code AND
length(t_tiers_payant.code) = 5 AND
to_char(base.cti_to_number(substr(t_tiers_payant.code,3,3)),'FM000') = substr(t_tiers_payant.code,3,3) THEN
substr(t_tiers_payant.code,3,3)
ELSE '' END
]))[2] AS caisse_gestionnaire_code
FROM pmsi.p_fiche5_rss
JOIN activite.p_sejour_pmsi ON p_fiche5_rss.rss_id = p_sejour_pmsi.rss_id
JOIN activite.p_sejours ON p_sejour_pmsi.no_sejour = p_sejours.no_sejour
JOIN activite.p_factures ON p_factures.no_sejour = p_sejours.no_sejour
LEFT JOIN activite.t_tiers_payant ON
p_factures.tiers_payant_1_id = t_tiers_payant.oid AND
p_factures.tiers_payant_1_id <> 0 AND
t_tiers_payant.type_tiers_payant_id <> 0
GROUP BY 1
) subview
WHERE p_fiche5_rss.oid = subview.oid AND
(
p_fiche5_rss.caisse_gestionnaire_code IS DISTINCT FROM subview.caisse_gestionnaire_code OR
p_fiche5_rss.caisse_gestionnaire_texte IS DISTINCT FROM subview.caisse_gestionnaire_texte
)
;
UPDATE pmsi.p_fiche5_rss
SET type_tarif = CASE WHEN type_etablissement NOT IN ('2','3') THEN '2' ELSE '1' END
FROM pmsi.p_rss
JOIN base.t_finess ON p_rss.finess = t_finess.code
WHERE p_fiche5_rss.rss_id = p_rss.oid AND
type_tarif IS DISTINCT FROM CASE WHEN type_etablissement NOT IN ('2','3') THEN '2' ELSE '1' END
;
UPDATE pmsi.p_fiche5_rss SET
montant_ticket_moderateur = subview.montant_ticket_moderateur,
montant_forfait_journalier = subview.montant_forfait_journalier,
nombre_forfait_journalier = subview.nombre_forfait_journalier,
taux_remboursement = subview.taux_remboursement,
facture_nb_exh = subview.facture_nb_exh,
facture_ghs_tarif = subview.facture_ghs_tarif,
facture_ghs_montant_total = subview.facture_ghs_montant_total,
facture_ghs_montant_amo = subview.facture_ghs_montant_amo,
facture_exb_montant_total = subview.facture_exb_montant_total,
facture_exb_montant_amo = subview.facture_exb_montant_amo,
facture_exh_montant_total = subview.facture_exh_montant_total,
facture_exh_montant_amo = subview.facture_exh_montant_amo,
coefficient_mco = subview.coefficient_mco,
facture_nb_src = subview.facture_nb_src,
facture_src_montant_total = subview.facture_src_montant_total,
facture_src_montant_amo = subview.facture_src_montant_amo,
facture_nb_stf = subview.facture_nb_stf,
facture_stf_montant_total = subview.facture_stf_montant_total,
facture_stf_montant_amo = subview.facture_stf_montant_amo,
facture_nb_rea = subview.facture_nb_rea,
facture_rea_montant_total = subview.facture_rea_montant_total,
facture_rea_montant_amo = subview.facture_rea_montant_amo
FROM
(
SELECT p_fiche5_rss.oid,
MAX(
CASE
WHEN t_prestations.code IN ('GHS') THEN p_rsf_detail.coefficient_mco
WHEN t_prestations.code IN ('I01') THEN 1
ELSE 0 END
) AS coefficient_mco,
MAX(
CASE WHEN t_prestations.code IN ('GHS','I01')
THEN p_rsf_detail.taux_remboursement
ELSE 0 END
) AS taux_remboursement,
SUM(
CASE WHEN t_prestations.code IN ('GHS','I01')
THEN p_rsf_detail.prix_unitaire
ELSE 0 END
) AS facture_ghs_tarif,
SUM(
CASE
WHEN t_prestations.code = 'I01' THEN p_rsf_detail.base_remboursement
WHEN t_prestations.code = 'GHS' AND coefficient >= 0.98 THEN p_rsf_detail.base_remboursement
WHEN t_prestations.code = 'GHS' AND coefficient < 0.98 THEN round(p_rsf_detail.prix_unitaire * p_rsf_detail.coefficient_mco,2)
ELSE 0 END
) AS facture_ghs_montant_total,
SUM(
CASE WHEN t_prestations.code IN ('GHS','I01')
THEN p_rsf_detail.sejour_remboursable ELSE 0 END
) AS facture_ghs_montant_amo,
SUM(
CASE WHEN t_prestations.code = 'GHS' AND coefficient < 0.98
THEN p_rsf_detail.base_remboursement - round(p_rsf_detail.prix_unitaire * p_rsf_detail.coefficient_mco,2) ELSE 0 END
) AS facture_exb_montant_total,
SUM(
CASE WHEN t_prestations.code = 'EXB'
THEN p_rsf_detail.sejour_remboursable ELSE 0 END
) AS facture_exb_montant_amo,
SUM(
CASE WHEN t_prestations.code = 'EXH'
THEN p_rsf_detail.nombre ELSE 0 END
) AS facture_nb_exh,
SUM(
CASE WHEN t_prestations.code = 'EXH'
THEN p_rsf_detail.base_remboursement ELSE 0 END
) AS facture_exh_montant_total,
SUM(
CASE WHEN t_prestations.code = 'EXH'
THEN p_rsf_detail.sejour_remboursable ELSE 0 END
) AS facture_exh_montant_amo,
SUM(
CASE WHEN t_prestations.code IN ('GHS', 'EXH', 'I01') AND p_rsf_detail.taux_remboursement < 100
THEN p_rsf_detail.base_remboursement - p_rsf_detail.sejour_remboursable
ELSE 0 END
) AS montant_ticket_moderateur,
SUM(
CASE WHEN t_prestations.code IN ('GHS', 'EXH', 'I01') AND p_rsf_detail.taux_remboursement = 100 OR t_prestations.code LIKE 'FJ%'
THEN p_rsf_detail.base_remboursement - p_rsf_detail.sejour_remboursable ELSE 0 END
) AS montant_forfait_journalier,
round(
SUM(
CASE WHEN t_prestations.code IN ('GHS', 'EXH', 'I01') AND p_rsf_detail.taux_remboursement = 100 OR t_prestations.code LIKE 'FJ%'
THEN p_rsf_detail.base_remboursement - p_rsf_detail.sejour_remboursable ELSE 0 END
) /
MAX(CASE WHEN p_rsf_detail.date_fin >= '20180101' THEN 20 ELSE 18 END)
,0) AS nombre_forfait_journalier,
SUM(
CASE WHEN t_prestations.code = 'SRC'
THEN p_rsf_detail.nombre ELSE 0 END
) AS facture_nb_src,
SUM(
CASE WHEN t_prestations.code = 'SRC'
THEN p_rsf_detail.base_remboursement ELSE 0 END
) AS facture_src_montant_total,
SUM(
CASE WHEN t_prestations.code = 'SRC'
THEN p_rsf_detail.sejour_remboursable ELSE 0 END
) AS facture_src_montant_amo,
SUM(
CASE WHEN t_prestations.code = 'STF'
THEN p_rsf_detail.nombre ELSE 0 END
) AS facture_nb_stf,
SUM(
CASE WHEN t_prestations.code = 'STF'
THEN p_rsf_detail.base_remboursement ELSE 0 END
) AS facture_stf_montant_total,
SUM(
CASE WHEN t_prestations.code = 'STF'
THEN p_rsf_detail.sejour_remboursable ELSE 0 END
) AS facture_stf_montant_amo,
SUM(
CASE WHEN t_prestations.code = 'REA'
THEN p_rsf_detail.nombre ELSE 0 END
) AS facture_nb_rea,
SUM(
CASE WHEN t_prestations.code = 'REA'
THEN p_rsf_detail.base_remboursement ELSE 0 END
) AS facture_rea_montant_total,
SUM(
CASE WHEN t_prestations.code = 'REA'
THEN p_rsf_detail.sejour_remboursable ELSE 0 END
) AS facture_rea_montant_amo
FROM pmsi.p_rsf_detail
JOIN pmsi.p_rss ON p_rsf_detail.rss_id = p_rss.oid
JOIN pmsi.t_ghm ON t_ghm.oid = p_rss.ghm_id
JOIN pmsi.p_fiche5_rss ON p_fiche5_rss.rss_id = p_rsf_detail.rss_id
JOIN pmsi.t_prestations ON prestation_id = t_prestations.oid AND t_prestations.code = ANY (Array['GHS','EXH','I01','FJA', 'FJR', 'SRC', 'STF', 'REA'])
WHERE p_rsf_detail.est_ligne_rss = '1' AND
(
t_prestations.code <> 'GHS' OR
t_ghm.code NOT LIKE '14%' OR
p_rsf_detail.ghs_id = p_rss.ghs_id
)
GROUP BY 1
) subview
WHERE p_fiche5_rss.oid = subview.oid
;
-- initialisaion codes dans scénarios
UPDATE pmsi.p_fiche5_rss SET
initial_ghm_code = CASE WHEN initial_ghm_code = '' THEN facture_ghm_code ELSE initial_ghm_code END,
initial_ghm_id = CASE WHEN initial_ghm_code = '' THEN facture_ghm_id ELSE initial_ghm_id END,
initial_ghs_code = CASE WHEN initial_ghs_code = '' THEN facture_ghs_code ELSE initial_ghs_code END,
initial_ghs_id = CASE WHEN initial_ghs_code = '' THEN facture_ghs_id ELSE initial_ghs_id END,
initial_dp_code = CASE WHEN initial_dp_code = '' THEN facture_dp_code ELSE initial_dp_code END,
initial_dp_id = CASE WHEN initial_dp_code = '' THEN facture_dp_id ELSE initial_dp_id END,
scenar1_ghm_code = CASE WHEN scenar1_ghm_code = '' THEN facture_ghm_code ELSE scenar1_ghm_code END,
scenar1_ghm_id = CASE WHEN scenar1_ghm_code = '' THEN facture_ghm_id ELSE scenar1_ghm_id END,
scenar1_ghs_code = CASE WHEN scenar1_ghs_code = '' THEN facture_ghs_code ELSE scenar1_ghs_code END,
scenar1_ghs_id = CASE WHEN scenar1_ghs_code = '' THEN facture_ghs_id ELSE scenar1_ghs_id END,
scenar1_dp_code = CASE WHEN scenar1_dp_code = '' THEN facture_dp_code ELSE scenar1_dp_code END,
scenar1_dp_id = CASE WHEN scenar1_dp_code = '' THEN facture_dp_id ELSE scenar1_dp_id END,
scenar1_rum_um_code = CASE WHEN scenar1_rum_um_code IS NULL THEN initial_rum_um_code ELSE scenar1_rum_um_code END,
scenar1_rum_dp_code = CASE WHEN scenar1_rum_dp_code IS NULL THEN initial_rum_dp_code ELSE scenar1_rum_dp_code END,
scenar1_rum_dr_code = CASE WHEN scenar1_rum_dr_code IS NULL THEN initial_rum_dr_code ELSE scenar1_rum_dr_code END,
scenar1_rum_da_code = CASE WHEN scenar1_rum_da_code IS NULL THEN initial_rum_da_code ELSE scenar1_rum_da_code END,
scenar2_ghm_code = CASE WHEN scenar2_ghm_code = '' THEN facture_ghm_code ELSE scenar2_ghm_code END,
scenar2_ghm_id = CASE WHEN scenar2_ghm_code = '' THEN facture_ghm_id ELSE scenar2_ghm_id END,
scenar2_ghs_code = CASE WHEN scenar2_ghs_code = '' THEN facture_ghs_code ELSE scenar2_ghs_code END,
scenar2_ghs_id = CASE WHEN scenar2_ghs_code = '' THEN facture_ghs_id ELSE scenar2_ghs_id END,
scenar2_dp_code = CASE WHEN scenar2_dp_code = '' THEN facture_dp_code ELSE scenar2_dp_code END,
scenar2_dp_id = CASE WHEN scenar2_dp_code = '' THEN facture_dp_id ELSE scenar2_dp_id END,
scenar2_rum_um_code = CASE WHEN scenar2_rum_um_code IS NULL THEN initial_rum_um_code ELSE scenar2_rum_um_code END,
scenar2_rum_dp_code = CASE WHEN scenar2_rum_dp_code IS NULL THEN initial_rum_dp_code ELSE scenar2_rum_dp_code END,
scenar2_rum_dr_code = CASE WHEN scenar2_rum_dr_code IS NULL THEN initial_rum_dr_code ELSE scenar2_rum_dr_code END,
scenar2_rum_da_code = CASE WHEN scenar2_rum_da_code IS NULL THEN initial_rum_da_code ELSE scenar2_rum_da_code END,
control_ghm_code = CASE WHEN control_ghm_code = '' THEN facture_ghm_code ELSE control_ghm_code END,
control_ghm_id = CASE WHEN control_ghm_code = '' THEN facture_ghm_id ELSE control_ghm_id END,
control_ghs_code = CASE WHEN control_ghs_code = '' THEN facture_ghs_code ELSE control_ghs_code END,
control_ghs_id = CASE WHEN control_ghs_code = '' THEN facture_ghs_id ELSE control_ghs_id END,
control_dp_code = CASE WHEN control_dp_code = '' THEN facture_dp_code ELSE control_dp_code END,
control_dp_id = CASE WHEN control_dp_code = '' THEN facture_dp_id ELSE control_dp_id END,
control_rum_um_code = CASE WHEN control_rum_um_code IS NULL THEN initial_rum_um_code ELSE control_rum_um_code END,
control_rum_dp_code = CASE WHEN control_rum_dp_code IS NULL THEN initial_rum_dp_code ELSE control_rum_dp_code END,
control_rum_dr_code = CASE WHEN control_rum_dr_code IS NULL THEN initial_rum_dr_code ELSE control_rum_dr_code END,
control_rum_da_code = CASE WHEN control_rum_da_code IS NULL THEN initial_rum_da_code ELSE control_rum_da_code END,
retenu_ghm_code = CASE WHEN retenu_ghm_code = '' THEN facture_ghm_code ELSE retenu_ghm_code END,
retenu_ghm_id = CASE WHEN retenu_ghm_code = '' THEN facture_ghm_id ELSE retenu_ghm_id END,
retenu_ghs_code = CASE WHEN retenu_ghs_code = '' THEN facture_ghs_code ELSE retenu_ghs_code END,
retenu_ghs_id = CASE WHEN retenu_ghs_code = '' THEN facture_ghs_id ELSE retenu_ghs_id END,
retenu_dp_code = CASE WHEN retenu_dp_code = '' THEN facture_dp_code ELSE retenu_dp_code END,
retenu_dp_id = CASE WHEN retenu_dp_code = '' THEN facture_dp_id ELSE retenu_dp_id END,
retenu_rum_um_code = CASE WHEN retenu_rum_um_code IS NULL THEN initial_rum_um_code ELSE retenu_rum_um_code END,
retenu_rum_dp_code = CASE WHEN retenu_rum_dp_code IS NULL THEN initial_rum_dp_code ELSE retenu_rum_dp_code END,
retenu_rum_dr_code = CASE WHEN retenu_rum_dr_code IS NULL THEN initial_rum_dr_code ELSE retenu_rum_dr_code END,
retenu_rum_da_code = CASE WHEN retenu_rum_da_code IS NULL THEN initial_rum_da_code ELSE retenu_rum_da_code END
;
-- Nombre dans entete
UPDATE pmsi.t_fiche5_enquete SET
nb_ogc = subview.nb_ogc,
nb_rss_ok = subview.nb_rss_ok,
nb_rss_ko = subview.nb_rss_ko
FROM
(
SELECT t_fiche5_enquete.oid,
count(*) AS nb_ogc,
SUM(CASE WHEN rss_id <> 0 THEN 1 ELSE 0 END) AS nb_rss_ok,
SUM(CASE WHEN rss_id = 0 THEN 1 ELSE 0 END) AS nb_rss_ko
FROM pmsi.t_fiche5_enquete
LEFT JOIN pmsi.p_fiche5_rss ON enquete_id = t_fiche5_enquete.oid
GROUP BY 1
) subview
WHERE t_fiche5_enquete.oid = subview.oid
;
return 'OK'
;
RETURN 'OK';
END;