|
|
return: text
|
|
|
lang: plpgsql
|
|
|
src: |
|
|
|
DECLARE
|
|
|
|
|
|
|
|
|
BEGIN
|
|
|
|
|
|
-- Oid 0 = Non renseigné
|
|
|
INSERT INTO activite.t_budget_cle (oid, code, texte, texte_court)
|
|
|
SELECT
|
|
|
0, '*NR', 'N/R', 'N/R'
|
|
|
WHERE 0 NOT IN (SELECT oid FROM activite.t_budget_cle)
|
|
|
;
|
|
|
|
|
|
-- Clés automatiques ?
|
|
|
IF NOT EXISTS (SELECT * FROM base.t_budget WHERE cle_budgetaire_activite IN ('CTIMEDSEJ','MEDSEJ','CTICLSUF','CTIFILMEDSEJ') LIMIT 1) THEN
|
|
|
return 'Aucune génération automatique';
|
|
|
END IF;
|
|
|
|
|
|
DROP TABLE IF EXISTS w_budget_settings;
|
|
|
CREATE TEMP TABLE w_budget_settings AS
|
|
|
SELECT (MAX(ARRAY[date_fin::text,oid::text]))[2]::bigint AS current_budget_id,
|
|
|
(MAX(ARRAY[date_fin::text,cle_budgetaire_activite]))[2]::text AS cle_budgetaire_activite,
|
|
|
(MAX(ARRAY[date_fin::text,classe_code]))[2]::text AS classe_code,
|
|
|
MAX(date_fin) AS date_fin,
|
|
|
NULL::date AS date_debut
|
|
|
FROM base.t_budget
|
|
|
;
|
|
|
UPDATE w_budget_settings
|
|
|
SET date_debut = t_budget.date_debut
|
|
|
FROM base.t_budget
|
|
|
WHERE t_budget.oid = current_budget_id
|
|
|
;
|
|
|
|
|
|
-- Génération des clés selon les médecins
|
|
|
IF EXISTS (SELECT * FROM w_budget_settings WHERE cle_budgetaire_activite IN ('CTIMEDSEJ','MEDSEJ')) THEN
|
|
|
|
|
|
DROP TABLE IF EXISTS w_medecins_utilises;
|
|
|
CREATE TEMP TABLE w_medecins_utilises AS
|
|
|
SELECT t_medecins.code, t_medecins.nom, t_medecins.prenom, t_medecins.specialite_id
|
|
|
FROM base.t_medecins
|
|
|
JOIN activite.t_medecins_administratifs ON t_medecins.oid = t_medecins_administratifs.medecin_id
|
|
|
JOIN w_budget_settings t_budget ON t_budget.cle_budgetaire_activite IN ('CTIMEDSEJ','MEDSEJ')
|
|
|
JOIN activite.p_sejours ON t_medecins_administratifs.oid = medecin_sejour_id AND date_sortie >= date(t_budget.date_debut - interval '1 year')
|
|
|
WHERE t_medecins.oid <> 0 AND t_medecins.code <> ''
|
|
|
GROUP BY 1,2,3,4
|
|
|
;
|
|
|
|
|
|
INSERT INTO w_medecins_utilises
|
|
|
SELECT t_medecins.code, t_medecins.nom, t_medecins.prenom, t_medecins.specialite_id
|
|
|
FROM base.t_medecins
|
|
|
JOIN w_budget_settings t_budget ON t_budget.cle_budgetaire_activite IN ('CTIMEDSEJ','MEDSEJ')
|
|
|
JOIN activite.t_budget_cle ON t_medecins.code = t_budget_cle.code
|
|
|
WHERE t_medecins.oid <> 0 AND t_medecins.code <> '' AND
|
|
|
t_medecins.code NOT IN (SELECT code FROM w_medecins_utilises) AND
|
|
|
t_medecins.specialite_id <> 0
|
|
|
GROUP BY 1,2,3,4
|
|
|
;
|
|
|
|
|
|
INSERT INTO w_medecins_utilises
|
|
|
SELECT t_medecins.code, t_medecins.nom, t_medecins.prenom, t_medecins.specialite_id
|
|
|
FROM base.t_medecins
|
|
|
JOIN w_budget_settings t_budget ON t_budget.cle_budgetaire_activite IN ('CTIMEDSEJ','MEDSEJ')
|
|
|
JOIN activite.t_budget_cle ON t_medecins.code = t_budget_cle.code
|
|
|
WHERE t_medecins.oid <> 0 AND t_medecins.code <> '' AND
|
|
|
t_medecins.code NOT IN (SELECT code FROM w_medecins_utilises)
|
|
|
GROUP BY 1,2,3,4
|
|
|
;
|
|
|
|
|
|
-- divers 1
|
|
|
INSERT INTO w_medecins_utilises(code, nom, prenom, specialite_id)
|
|
|
SELECT
|
|
|
'*SP'||t_specialites_medecin.code||'-1',
|
|
|
'MEDECIN 1 EN '||t_specialites_medecin.texte|| ' ('||t_specialites_medecin.code|| ')',
|
|
|
'',
|
|
|
w_medecins_utilises.specialite_id
|
|
|
FROM w_medecins_utilises
|
|
|
JOIN base.t_specialites_medecin ON specialite_id = t_specialites_medecin.oid
|
|
|
JOIN w_budget_settings ON cle_budgetaire_activite = 'CTIMEDSEJ'
|
|
|
WHERE specialite_id <> 0
|
|
|
GROUP BY 1,2,3,4
|
|
|
;
|
|
|
-- divers 2
|
|
|
INSERT INTO w_medecins_utilises(code, nom, prenom, specialite_id)
|
|
|
SELECT
|
|
|
'*SP'||t_specialites_medecin.code||'-2',
|
|
|
'MEDECIN 2 EN '||t_specialites_medecin.texte|| ' ('||t_specialites_medecin.code|| ')',
|
|
|
'',
|
|
|
w_medecins_utilises.specialite_id
|
|
|
FROM w_medecins_utilises
|
|
|
JOIN base.t_specialites_medecin ON specialite_id = t_specialites_medecin.oid
|
|
|
JOIN w_budget_settings ON cle_budgetaire_activite = 'CTIMEDSEJ'
|
|
|
WHERE specialite_id <> 0
|
|
|
GROUP BY 1,2,3,4
|
|
|
;
|
|
|
-- clés globales
|
|
|
INSERT INTO w_medecins_utilises(code, nom, prenom, specialite_id)
|
|
|
SELECT
|
|
|
'*GLOBAL',
|
|
|
'Budget Total',
|
|
|
'',
|
|
|
0::bigint AS specialite_id
|
|
|
FROM w_budget_settings
|
|
|
WHERE cle_budgetaire_activite = 'CTIMEDSEJ'
|
|
|
;
|
|
|
|
|
|
|
|
|
-- Clés = Médecins séjours
|
|
|
INSERT INTO activite.t_budget_cle (code, texte, texte_court)
|
|
|
SELECT
|
|
|
t_medecins.code, MAX(t_medecins.nom || ' ' || t_medecins.prenom), MAX(t_medecins.nom || ' ' || t_medecins.prenom)
|
|
|
FROM w_medecins_utilises t_medecins
|
|
|
WHERE t_medecins.code NOT IN (SELECT code FROM activite.t_budget_cle)
|
|
|
GROUP BY 1
|
|
|
;
|
|
|
|
|
|
|
|
|
UPDATE activite.t_budget_cle SET
|
|
|
texte = subview.texte,
|
|
|
texte_court = subview.texte
|
|
|
FROM
|
|
|
(
|
|
|
SELECT code, MAX(nom || ' ' || prenom) AS texte
|
|
|
FROM w_medecins_utilises
|
|
|
GROUP BY 1
|
|
|
) subview
|
|
|
WHERE t_budget_cle.code = subview.code AND
|
|
|
t_budget_cle.texte IS DISTINCT FROM subview.texte
|
|
|
;
|
|
|
|
|
|
-- Règles standard Médecins séjours
|
|
|
INSERT INTO activite.t_budget_cle_rule (code, texte, budget_cle_id, priorite, liste_medecin)
|
|
|
SELECT
|
|
|
''::text,
|
|
|
MAX(t_budget_cle.texte) || ' - Standard',
|
|
|
MAX(t_budget_cle.oid),
|
|
|
5000,
|
|
|
'(R) ' || t_budget_cle.code
|
|
|
FROM activite.t_budget_cle
|
|
|
JOIN w_budget_settings t_budget ON t_budget.cle_budgetaire_activite IN ('CTIMEDSEJ','MEDSEJ')
|
|
|
JOIN base.t_medecins ON t_budget_cle.code = t_medecins.code
|
|
|
LEFT JOIN activite.t_budget_cle_rule ON
|
|
|
t_budget_cle.oid = budget_cle_id AND
|
|
|
priorite = 5000
|
|
|
WHERE t_budget_cle.oid <> 0 AND
|
|
|
t_budget_cle.code NOT LIKE '*SP%' AND
|
|
|
t_budget_cle.code NOT LIKE '*GL%' AND
|
|
|
t_budget_cle_rule.oid IS NULL
|
|
|
GROUP BY 5;
|
|
|
|
|
|
UPDATE activite.t_budget_cle_rule SET
|
|
|
texte = subview.texte,
|
|
|
liste_medecin = subview.liste_medecin
|
|
|
FROM
|
|
|
(
|
|
|
SELECT
|
|
|
t_budget_cle_rule.oid,
|
|
|
MAX(t_budget_cle.texte) || ' - Standard' AS texte,
|
|
|
'(R) ' || MAX(t_budget_cle.code) AS liste_medecin
|
|
|
FROM activite.t_budget_cle
|
|
|
JOIN w_budget_settings t_budget ON t_budget.cle_budgetaire_activite IN ('CTIMEDSEJ','MEDSEJ')
|
|
|
JOIN activite.t_budget_cle_rule ON
|
|
|
t_budget_cle.oid = budget_cle_id AND
|
|
|
priorite = 5000
|
|
|
GROUP BY 1
|
|
|
HAVING
|
|
|
t_budget_cle_rule.texte <> (MAX(t_budget_cle.texte) || ' - Standard') OR
|
|
|
t_budget_cle_rule.liste_medecin <> ('(R) ' || MAX(t_budget_cle.code))
|
|
|
) subview
|
|
|
WHERE t_budget_cle_rule.oid = subview.oid
|
|
|
;
|
|
|
|
|
|
-- Suppression des clés pour des spécialités non utilisées (médecins réaffectés)
|
|
|
DELETE FROM activite.t_budget_cle
|
|
|
WHERE code LIKE '*SP%' AND
|
|
|
substr(code,4,length(code)-5) NOT IN
|
|
|
(SELECT t_specialites_medecin.code
|
|
|
FROM w_medecins_utilises
|
|
|
JOIN base.t_specialites_medecin ON specialite_id = t_specialites_medecin.oid
|
|
|
WHERE t_specialites_medecin.code IS NOT NULL) AND
|
|
|
t_budget_cle.oid NOT IN (SELECT budget_cle_id FROM activite.t_budget_cle_budget WHERE budget <> 0)
|
|
|
;
|
|
|
|
|
|
DELETE FROM activite.t_budget_cle_budget
|
|
|
WHERE budget = 0 AND budget_cle_id NOT IN (SELECT oid FROM activite.t_budget_cle)
|
|
|
;
|
|
|
|
|
|
-- Règles pour médecins divers (non prévus dans budget)
|
|
|
-- En attente
|
|
|
|
|
|
-- Classes par spécialité
|
|
|
INSERT INTO activite.t_classes(
|
|
|
code, texte, table_id, is_cti, sequence
|
|
|
)
|
|
|
SELECT 'CTI_SPE_BUDG', 'Spécialités budgétaires', t_listes_tables.oid, '1', 1
|
|
|
FROM activite.t_listes_tables
|
|
|
JOIN w_budget_settings t_budget ON t_budget.cle_budgetaire_activite IN ('CTIMEDSEJ','MEDSEJ')
|
|
|
LEFT JOIN activite.t_classes ON t_classes.table_id = t_listes_tables.oid
|
|
|
LEFT JOIN activite.t_classes t_classes_s1 ON t_classes_s1.table_id = t_listes_tables.oid AND t_classes_s1.sequence = 1
|
|
|
WHERE t_listes_tables.code = 'BUDGETCLE' AND
|
|
|
t_classes.oid IS NULL AND
|
|
|
t_classes_s1.oid IS NULL
|
|
|
GROUP BY 3
|
|
|
;
|
|
|
|
|
|
-- Classe à alimenter
|
|
|
DROP TABLE IF EXISTS w_classes;
|
|
|
CREATE TEMP TABLE w_classes AS
|
|
|
SELECT
|
|
|
COALESCE((MIN(ARRAY[CASE WHEN t_classes.code = 'CTI_SPE_BUDG' THEN '1' WHEN t_classes.sequence = 1 THEN '2' ELSE '9' END, t_classes.oid::text]))[2]::bigint,0) AS oid
|
|
|
FROM activite.t_classes
|
|
|
JOIN activite.t_listes_tables ON t_classes.table_id = t_listes_tables.oid
|
|
|
WHERE t_listes_tables.code = 'BUDGETCLE'
|
|
|
;
|
|
|
|
|
|
DELETE FROM w_classes
|
|
|
WHERE oid = 0
|
|
|
;
|
|
|
|
|
|
DROP TABLE IF EXISTS w_sections;
|
|
|
CREATE TEMP TABLE w_sections AS
|
|
|
SELECT
|
|
|
t_budget_cle.oid AS budget_cle_id,
|
|
|
(MAX(ARRAY[to_char(t_medecins.specialite_id,'FM0000000000000'),CASE WHEN t_medecins.specialite_id <> 0 THEN t_specialites_medecin.code ELSE '****' END]))[2]::text AS section_code,
|
|
|
(MAX(ARRAY[to_char(t_medecins.specialite_id,'FM0000000000000'),CASE WHEN t_medecins.specialite_id <> 0 THEN t_specialites_medecin.texte ELSE 'SANS SPECIALITE' END]))[2]::text AS section_texte,
|
|
|
0::bigint AS section_id
|
|
|
FROM w_medecins_utilises t_medecins
|
|
|
JOIN base.t_specialites_medecin ON t_medecins.specialite_id = t_specialites_medecin.oid
|
|
|
JOIN w_budget_settings t_budget ON t_budget.cle_budgetaire_activite IN ('CTIMEDSEJ','MEDSEJ')
|
|
|
JOIN activite.t_budget_cle ON t_budget_cle.code = t_medecins.code
|
|
|
GROUP BY 1
|
|
|
;
|
|
|
|
|
|
INSERT INTO activite.t_classes_sections (code, classe_id, texte)
|
|
|
SELECT section_code, w_classes.oid, MAX(section_texte)
|
|
|
FROM w_classes
|
|
|
JOIN w_sections ON 1=1
|
|
|
LEFT JOIN activite.t_classes_sections ON classe_id = w_classes.oid AND
|
|
|
t_classes_sections.code = w_sections.section_code
|
|
|
WHERE w_classes.oid <> 0 AND t_classes_sections.oid IS NULL
|
|
|
GROUP BY 1,2
|
|
|
ORDER BY 1
|
|
|
;
|
|
|
|
|
|
|
|
|
UPDATE w_sections
|
|
|
SET section_id = t_classes_sections.oid
|
|
|
FROM activite.t_classes_sections
|
|
|
JOIN w_classes ON t_classes_sections.classe_id = w_classes.oid
|
|
|
WHERE section_code = t_classes_sections.code
|
|
|
;
|
|
|
|
|
|
UPDATE activite.t_classes_sections
|
|
|
SET texte = subview.section_texte
|
|
|
FROM
|
|
|
(
|
|
|
SELECT section_id, section_code, w_classes.oid, MAX(section_texte) AS section_texte
|
|
|
FROM w_classes
|
|
|
JOIN w_sections ON 1=1
|
|
|
GROUP BY 1,2,3
|
|
|
ORDER BY 1
|
|
|
) subview
|
|
|
WHERE t_classes_sections.oid = section_id AND
|
|
|
t_classes_sections.texte IS DISTINCT FROM subview.section_texte
|
|
|
;
|
|
|
|
|
|
WITH subview AS
|
|
|
(SELECT section_id, to_id
|
|
|
FROM activite.t_classes_sections_elements
|
|
|
JOIN activite.t_classes_sections ON t_classes_sections_elements.section_id = t_classes_sections.oid
|
|
|
JOIN w_classes ON t_classes_sections.classe_id = w_classes.oid
|
|
|
)
|
|
|
INSERT INTO activite.t_classes_sections_elements
|
|
|
SELECT section_id, budget_cle_id
|
|
|
FROM w_sections
|
|
|
WHERE budget_cle_id NOT IN (SELECT to_id FROM subview)
|
|
|
;
|
|
|
|
|
|
WITH subview AS
|
|
|
(SELECT t_classes_sections_elements.section_id AS section_id, w_sections.section_id AS new_section_id, to_id
|
|
|
FROM activite.t_classes_sections_elements
|
|
|
JOIN activite.t_classes_sections ON t_classes_sections_elements.section_id = t_classes_sections.oid
|
|
|
JOIN w_classes ON t_classes_sections.classe_id = w_classes.oid
|
|
|
JOIN w_sections ON w_sections.budget_cle_id = t_classes_sections_elements.to_id
|
|
|
)
|
|
|
UPDATE activite.t_classes_sections_elements
|
|
|
SET section_id = subview.new_section_id
|
|
|
FROM subview
|
|
|
WHERE subview.to_id = t_classes_sections_elements.to_id AND
|
|
|
subview.section_id = t_classes_sections_elements.section_id AND
|
|
|
t_classes_sections_elements.section_id <> subview.new_section_id
|
|
|
;
|
|
|
|
|
|
-- Suppression des enfants avec clé budgétaire supprimée
|
|
|
DELETE
|
|
|
FROM activite.t_classes_sections_elements
|
|
|
USING activite.t_classes_sections
|
|
|
JOIN w_classes ON classe_id = w_classes.oid
|
|
|
WHERE section_id = t_classes_sections.oid AND
|
|
|
to_id NOT IN (SELECT oid FROM activite.t_budget_cle)
|
|
|
;
|
|
|
|
|
|
-- Suppression des clés sans enfant
|
|
|
DELETE FROM activite.t_classes_sections
|
|
|
WHERE oid IN
|
|
|
(
|
|
|
SELECT t_classes_sections.oid
|
|
|
FROM activite.t_classes_sections
|
|
|
JOIN w_classes ON classe_id = w_classes.oid
|
|
|
WHERE t_classes_sections.oid NOT IN (SELECT section_id FROM activite.t_classes_sections_elements)
|
|
|
)
|
|
|
;
|
|
|
|
|
|
PERFORM base.cti_update_classes('activite', 't_budget_cle', 'BUDGETCLE','');
|
|
|
PERFORM activite.cti_reorganize_indicateur_condition();
|
|
|
|
|
|
END IF;
|
|
|
|
|
|
-- Génération selon classes d'UF
|
|
|
IF EXISTS (SELECT * FROM w_budget_settings WHERE cle_budgetaire_activite IN ('CTICLSUF')) THEN
|
|
|
|
|
|
|
|
|
|
|
|
DROP TABLE IF EXISTS w_budget_cle;
|
|
|
CREATE TEMP TABLE w_budget_cle AS
|
|
|
SELECT cle_code, cle_texte, base.cti_group_concat_without_sep(uf_code || ' ') AS cle_rule
|
|
|
FROM
|
|
|
(
|
|
|
SELECT t_classes_sections.code AS cle_code, t_classes_sections.texte AS cle_texte, t_unites_fonctionnelles.code AS uf_code
|
|
|
FROM activite.t_classes_sections_elements
|
|
|
JOIN activite.t_classes_sections ON t_classes_sections_elements.section_id = t_classes_sections.oid
|
|
|
JOIN activite.t_classes ON t_classes_sections.classe_id = t_classes.oid
|
|
|
JOIN activite.t_unites_fonctionnelles ON t_classes_sections_elements.to_id = t_unites_fonctionnelles.oid
|
|
|
JOIN w_budget_settings t_budget ON t_budget.cle_budgetaire_activite IN ('CTICLSUF')
|
|
|
WHERE t_classes.code = t_budget.classe_code
|
|
|
ORDER BY 1,2,3
|
|
|
) subview
|
|
|
GROUP BY 1,2
|
|
|
ORDER BY 1
|
|
|
;
|
|
|
|
|
|
INSERT INTO activite.t_budget_cle (code, texte, texte_court)
|
|
|
SELECT cle_code, cle_texte, cle_texte
|
|
|
FROM w_budget_cle
|
|
|
WHERE cle_code NOT IN (SELECT code FROM activite.t_budget_cle WHERE code IS NOT NULL)
|
|
|
;
|
|
|
|
|
|
|
|
|
INSERT INTO activite.t_budget_cle_rule (code, texte, budget_cle_id, priorite, liste_uf)
|
|
|
SELECT
|
|
|
t_budget_cle.code || '-STD',
|
|
|
MAX(t_budget_cle.texte) || ' - Standard',
|
|
|
MAX(t_budget_cle.oid),
|
|
|
5000,
|
|
|
cle_rule
|
|
|
FROM activite.t_budget_cle
|
|
|
JOIN w_budget_cle ON t_budget_cle.code = w_budget_cle.cle_code
|
|
|
LEFT JOIN activite.t_budget_cle_rule ON
|
|
|
t_budget_cle.oid = budget_cle_id AND
|
|
|
priorite = 5000
|
|
|
WHERE t_budget_cle.oid <> 0 AND
|
|
|
t_budget_cle_rule.oid IS NULL
|
|
|
GROUP BY 1,5;
|
|
|
|
|
|
UPDATE activite.t_budget_cle_rule SET
|
|
|
code = subview.code,
|
|
|
texte = subview.texte,
|
|
|
liste_uf = subview.cle_rule
|
|
|
FROM
|
|
|
(
|
|
|
SELECT
|
|
|
t_budget_cle_rule.oid,
|
|
|
MAX(t_budget_cle.code) || '-STD' AS code,
|
|
|
MAX(t_budget_cle.texte) || ' - Standard' AS texte,
|
|
|
MAX(cle_rule) AS cle_rule
|
|
|
FROM activite.t_budget_cle
|
|
|
JOIN w_budget_cle ON t_budget_cle.code = w_budget_cle.cle_code
|
|
|
JOIN activite.t_budget_cle_rule ON
|
|
|
t_budget_cle.oid = budget_cle_id AND
|
|
|
priorite = 5000
|
|
|
GROUP BY 1
|
|
|
HAVING
|
|
|
t_budget_cle_rule.code <> (MAX(t_budget_cle.code) || '-STD') OR
|
|
|
t_budget_cle_rule.texte <> (MAX(t_budget_cle.texte) || ' - Standard') OR
|
|
|
t_budget_cle_rule.liste_uf <> MAX(cle_rule)
|
|
|
) subview
|
|
|
WHERE t_budget_cle_rule.oid = subview.oid
|
|
|
;
|
|
|
|
|
|
DELETE
|
|
|
FROM activite.t_budget_cle_rule
|
|
|
WHERE priorite = 5000 AND
|
|
|
code NOT IN (SELECT cle_code || '-STD' FROM w_budget_cle)
|
|
|
;
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
END IF;
|
|
|
|
|
|
-- Génération des clés filiere et medecin
|
|
|
IF EXISTS (SELECT * FROM w_budget_settings WHERE cle_budgetaire_activite IN ('CTIFILMEDSEJ')) THEN
|
|
|
DROP TABLE IF EXISTS w_cle_utilise;
|
|
|
CREATE TEMP TABLE w_cle_utilise AS
|
|
|
SELECT
|
|
|
t_medecins_administratifs.medecin_id,
|
|
|
t_medecins.code AS medecin_code,
|
|
|
t_medecins.nom || ' ' || t_medecins.prenom AS medecin_texte,
|
|
|
t_medecins.specialite_id,
|
|
|
filiere_soin_principale_id AS filiere_soin_id,
|
|
|
t_filiere_soin.code AS filiere_soin_code,
|
|
|
t_filiere_soin.texte AS filiere_soin_texte,
|
|
|
replace(t_filiere_soin.code,'.','')||'#'||t_medecins.code AS cle_budget_code,
|
|
|
t_filiere_soin.code || ' ' || t_filiere_soin.texte||'. Medecin: '||t_medecins.nom || ' ' || t_medecins.prenom AS cle_budget_texte
|
|
|
FROM activite.p_sejours
|
|
|
JOIN activite.t_medecins_administratifs ON t_medecins_administratifs.oid = medecin_sejour_id
|
|
|
JOIN activite.t_filiere_soin ON filiere_soin_principale_id = t_filiere_soin.oid
|
|
|
JOIN base.t_medecins ON t_medecins.oid = t_medecins_administratifs.medecin_id
|
|
|
JOIN w_budget_settings t_budget ON t_budget.cle_budgetaire_activite IN ('CTIFILMEDSEJ')
|
|
|
WHERE p_sejours.date_sortie >= date(t_budget.date_debut - interval '1 year') AND
|
|
|
medecin_sejour_id > 0 AND
|
|
|
t_medecins_administratifs.medecin_id > 0 AND
|
|
|
t_medecins.code <> '' AND
|
|
|
filiere_soin_principale_id > 0
|
|
|
GROUP BY 1,2,3,4,5,6,7,8,9
|
|
|
;
|
|
|
|
|
|
|
|
|
-- divers 1
|
|
|
INSERT INTO w_cle_utilise(medecin_id, medecin_code, medecin_texte, filiere_soin_id, filiere_soin_code, filiere_soin_texte, cle_budget_code, cle_budget_texte)
|
|
|
SELECT
|
|
|
0::bigint AS medecin_id,
|
|
|
'*FS'||filiere_soin_code||'-1',
|
|
|
'MEDECIN 1 EN '||filiere_soin_texte|| ' ('||filiere_soin_code|| ')',
|
|
|
filiere_soin_id,
|
|
|
filiere_soin_code,
|
|
|
filiere_soin_texte,
|
|
|
replace(filiere_soin_code,'.','')||'#*DIV1' AS cle_budget_code,
|
|
|
filiere_soin_code || ' ' || filiere_soin_texte||'. Medecin: Divers 1' AS cle_budget_texte
|
|
|
FROM w_cle_utilise
|
|
|
JOIN w_budget_settings ON cle_budgetaire_activite = 'CTIFILMEDSEJ'
|
|
|
GROUP BY 1,2,3,4,5,6,7,8
|
|
|
;
|
|
|
-- divers 2
|
|
|
INSERT INTO w_cle_utilise(medecin_id, medecin_code, medecin_texte, filiere_soin_id, filiere_soin_code, filiere_soin_texte, cle_budget_code, cle_budget_texte)
|
|
|
SELECT
|
|
|
0::bigint AS medecin_id,
|
|
|
'*FS'||filiere_soin_code||'-1',
|
|
|
'MEDECIN 1 EN '||filiere_soin_texte|| ' ('||filiere_soin_code|| ')',
|
|
|
filiere_soin_id,
|
|
|
filiere_soin_code,
|
|
|
filiere_soin_texte,
|
|
|
replace(filiere_soin_code,'.','')||'#*DIV2' AS cle_budget_code,
|
|
|
filiere_soin_code || ' ' || filiere_soin_texte||'. Medecin: Divers 2' AS cle_budget_texte
|
|
|
FROM w_cle_utilise
|
|
|
JOIN w_budget_settings ON cle_budgetaire_activite = 'CTIFILMEDSEJ'
|
|
|
GROUP BY 1,2,3,4,5,6,7,8
|
|
|
;
|
|
|
|
|
|
INSERT INTO w_cle_utilise(medecin_id, medecin_code, medecin_texte, filiere_soin_id, filiere_soin_code, filiere_soin_texte, cle_budget_code, cle_budget_texte)
|
|
|
SELECT
|
|
|
0::bigint AS medecin_id,
|
|
|
'*ZZ',
|
|
|
'AUTRES',
|
|
|
0::bigint AS filiere_soin_id,
|
|
|
''::text AS filiere_soin_code,
|
|
|
''::text AS filiere_soin_texte,
|
|
|
'*ZZ' AS cle_budget_code,
|
|
|
'AUTRES' AS cle_budget_texte
|
|
|
FROM w_cle_utilise
|
|
|
JOIN w_budget_settings ON cle_budgetaire_activite = 'CTIFILMEDSEJ'
|
|
|
GROUP BY 1,2,3,4,5,6,7,8
|
|
|
;
|
|
|
-- clés globales
|
|
|
INSERT INTO w_cle_utilise(medecin_id, medecin_code, medecin_texte, filiere_soin_id, filiere_soin_code, filiere_soin_texte, cle_budget_code, cle_budget_texte)
|
|
|
SELECT
|
|
|
0::bigint AS medecin_id,
|
|
|
'*GLOBAL',
|
|
|
'Budget Total',
|
|
|
0::bigint AS filiere_soin_id,
|
|
|
''::text AS filiere_soin_code,
|
|
|
''::text AS filiere_soin_texte,
|
|
|
'*GLOBAL'::text AS cle_budget_code,
|
|
|
'Budget Total'::text AS cle_budget_texte
|
|
|
FROM w_budget_settings
|
|
|
WHERE cle_budgetaire_activite = 'CTIFILMEDSEJ'
|
|
|
;
|
|
|
|
|
|
|
|
|
-- Clés = Médecins séjours
|
|
|
INSERT INTO activite.t_budget_cle (code, texte, texte_court)
|
|
|
SELECT
|
|
|
cle_budget_code, cle_budget_texte, cle_budget_texte
|
|
|
FROM w_cle_utilise
|
|
|
WHERE cle_budget_code NOT IN (SELECT code FROM activite.t_budget_cle)
|
|
|
;
|
|
|
|
|
|
|
|
|
UPDATE activite.t_budget_cle SET
|
|
|
texte = w_cle_utilise.cle_budget_texte,
|
|
|
texte_court = w_cle_utilise.cle_budget_texte
|
|
|
FROM w_cle_utilise
|
|
|
WHERE t_budget_cle.code = w_cle_utilise.cle_budget_code AND
|
|
|
t_budget_cle.texte IS DISTINCT FROM w_cle_utilise.cle_budget_texte
|
|
|
;
|
|
|
|
|
|
|
|
|
-- Règles standard Médecins séjours
|
|
|
DROP TABLE IF EXISTS w_filiere_soin_rule;
|
|
|
CREATE TEMP TABLE w_filiere_soin_rule AS
|
|
|
SELECT
|
|
|
t_filiere_soin_rule.oid AS filiere_soin_rule_id,
|
|
|
row_number() OVER (PARTITION BY filiere_soin_id ORDER BY priorite) AS rule_sequence,
|
|
|
filiere_soin_id,
|
|
|
CASE WHEN priorite <> 0 THEN priorite WHEN liste_diagnostic_principal <> '' THEN 90000 ELSE 999999 END AS priorite,
|
|
|
CASE WHEN liste_specialite <> '' THEN '1' ELSE '0' END AS a_liste_specialite,
|
|
|
string_to_array(translate(liste_specialite,'*,','% '),' ') AS liste_specialite,
|
|
|
NULL::bigint[] AS liste_specialite_id ,
|
|
|
CASE WHEN liste_medecin <> '' THEN '1' ELSE '0' END AS a_liste_medecin,
|
|
|
string_to_array(CASE WHEN liste_medecin NOT LIKE '%**%' THEN translate(liste_medecin,'*,','% ') ELSE liste_medecin END,' ') AS liste_medecin,
|
|
|
NULL::bigint[] AS liste_medecin_id
|
|
|
FROM activite.t_filiere_soin_rule t_filiere_soin_rule
|
|
|
JOIN activite.t_filiere_soin t_filiere_soin ON filiere_soin_id = t_filiere_soin.oid
|
|
|
ORDER BY filiere_soin_id, priorite
|
|
|
;
|
|
|
|
|
|
UPDATE w_filiere_soin_rule
|
|
|
SET liste_specialite_id = (SELECT base.cti_group_array3(oid) FROM base.t_specialites_medecin WHERE code LIKE ANY (liste_specialite))
|
|
|
WHERE a_liste_specialite = '1'
|
|
|
;
|
|
|
|
|
|
UPDATE w_filiere_soin_rule
|
|
|
SET liste_medecin_id = (
|
|
|
SELECT base.cti_group_array3(t_medecins_administratifs.oid)
|
|
|
FROM activite.t_medecins_administratifs
|
|
|
LEFT JOIN base.t_medecins ON t_medecins_administratifs.medecin_id = t_medecins.oid
|
|
|
WHERE (
|
|
|
t_medecins_administratifs.oid <> 0 AND
|
|
|
t_medecins_administratifs.code <> '' AND
|
|
|
t_medecins_administratifs.code LIKE ANY (liste_medecin) AND liste_medecin[1] <> '(R)'
|
|
|
) OR
|
|
|
(
|
|
|
t_medecins_administratifs.oid IN
|
|
|
(
|
|
|
SELECT
|
|
|
to_id
|
|
|
FROM activite.t_classes
|
|
|
JOIN activite.t_classes_sections ON t_classes_sections.classe_id = t_classes.oid
|
|
|
JOIN activite.t_classes_sections_elements ON t_classes_sections_elements.section_id = t_classes_sections.oid
|
|
|
WHERE '[CLASSE:'||t_classes.code||':'||t_classes_sections.code||']' = ANY(liste_medecin)
|
|
|
)
|
|
|
) OR
|
|
|
(
|
|
|
t_medecins.oid <> 0 AND
|
|
|
t_medecins.code <> '' AND
|
|
|
t_medecins.code LIKE ANY (liste_medecin) AND liste_medecin[1] = '(R)'
|
|
|
)
|
|
|
)
|
|
|
WHERE a_liste_medecin = '1'
|
|
|
;
|
|
|
|
|
|
DROP TABLE IF EXISTS w_budget_cle_rule;
|
|
|
CREATE TEMP TABLE w_budget_cle_rule AS
|
|
|
SELECT
|
|
|
t_budget_cle.code || '-' || rule_sequence::text AS code,
|
|
|
t_budget_cle.texte || ' (auto)' AS texte,
|
|
|
t_budget_cle.oid AS budget_cle_id,
|
|
|
t_filiere_soin_rule.priorite,
|
|
|
t_filiere_soin_rule.liste_diagnostic_principal,
|
|
|
t_filiere_soin_rule.liste_diagnostic_relie,
|
|
|
t_filiere_soin_rule.liste_diagnostic_associe,
|
|
|
t_filiere_soin_rule.liste_acte,
|
|
|
t_filiere_soin_rule.liste_ghm,
|
|
|
''::text AS liste_specialite,
|
|
|
array_to_string(base.cti_array_accum(DISTINCT t_medecins_administratifs.code),' ') AS liste_medecin,
|
|
|
t_filiere_soin_rule.liste_finess,
|
|
|
t_filiere_soin_rule.liste_service,
|
|
|
t_filiere_soin_rule.liste_rubrique,
|
|
|
t_filiere_soin_rule.liste_sauf_ghm,
|
|
|
t_filiere_soin_rule.liste_activite,
|
|
|
t_filiere_soin_rule.liste_type_sejour,
|
|
|
GREATEST(liste_unite_fonctionnelle_entree,t_filiere_soin_rule.liste_unite_fonctionnelle) AS liste_uf
|
|
|
FROM activite.t_budget_cle
|
|
|
JOIN w_cle_utilise ON t_budget_cle.code = cle_budget_code
|
|
|
JOIN w_budget_settings t_budget ON t_budget.cle_budgetaire_activite IN ('CTIFILMEDSEJ')
|
|
|
JOIN activite.t_filiere_soin_rule ON w_cle_utilise.filiere_soin_id = t_filiere_soin_rule.filiere_soin_id
|
|
|
JOIN activite.t_medecins_administratifs ON
|
|
|
w_cle_utilise.medecin_id <> 0 AND
|
|
|
w_cle_utilise.medecin_id = t_medecins_administratifs.medecin_id
|
|
|
JOIN w_filiere_soin_rule ON
|
|
|
t_filiere_soin_rule.oid = w_filiere_soin_rule.filiere_soin_rule_id AND
|
|
|
(a_liste_medecin = '0' OR t_medecins_administratifs.oid = ANY (liste_medecin_id)) AND
|
|
|
(a_liste_specialite = '0' OR w_cle_utilise.specialite_id = ANY (liste_specialite_id))
|
|
|
WHERE cle_budget_code NOT LIKE '%*DIV%'
|
|
|
GROUP BY 1,2,3,4,5,6,7,8,9,10,12,13,14,15,16,17,18
|
|
|
;
|
|
|
|
|
|
|
|
|
INSERT INTO w_budget_cle_rule
|
|
|
SELECT
|
|
|
t_budget_cle.code AS code,
|
|
|
t_budget_cle.texte || ' (auto)' AS texte,
|
|
|
t_budget_cle.oid AS budget_cle_id,
|
|
|
99999 AS priorite,
|
|
|
''::text AS liste_diagnostic_principal,
|
|
|
''::text AS liste_diagnostic_relie,
|
|
|
''::text AS liste_diagnostic_associe,
|
|
|
''::text AS liste_acte,
|
|
|
''::text AS liste_ghm,
|
|
|
''::text AS liste_specialite,
|
|
|
''::text AS liste_medecin,
|
|
|
''::text AS liste_finess,
|
|
|
''::text AS liste_service,
|
|
|
''::text AS liste_rubrique,
|
|
|
''::text AS liste_sauf_ghm,
|
|
|
''::text AS liste_activite,
|
|
|
''::text AS liste_type_sejour,
|
|
|
''::text AS liste_uf
|
|
|
FROM activite.t_budget_cle
|
|
|
WHERE t_budget_cle.code = '*ZZ'
|
|
|
;
|
|
|
DELETE FROM w_budget_cle_rule
|
|
|
USING
|
|
|
(
|
|
|
SELECT
|
|
|
budget_cle_id,
|
|
|
liste_diagnostic_principal,
|
|
|
liste_diagnostic_relie,
|
|
|
liste_diagnostic_associe,
|
|
|
liste_acte,
|
|
|
liste_ghm,
|
|
|
liste_specialite,
|
|
|
liste_medecin,
|
|
|
liste_finess,
|
|
|
liste_service,
|
|
|
liste_rubrique,
|
|
|
liste_sauf_ghm,
|
|
|
liste_activite,
|
|
|
liste_type_sejour,
|
|
|
liste_uf,
|
|
|
(MIN(ARRAY[liste_specialite,priorite::text]))[2]::bigint AS keep_priorite
|
|
|
FROM w_budget_cle_rule
|
|
|
WHERE liste_medecin <> ''
|
|
|
GROUP BY 1,2,3,4,5,6,7,8,9,10,11,12,13,14,15
|
|
|
HAVING count(*) > 1
|
|
|
) subview
|
|
|
WHERE
|
|
|
w_budget_cle_rule.budget_cle_id = subview.budget_cle_id AND
|
|
|
w_budget_cle_rule.liste_diagnostic_principal = subview.liste_diagnostic_principal AND
|
|
|
w_budget_cle_rule.liste_diagnostic_relie = subview.liste_diagnostic_relie AND
|
|
|
w_budget_cle_rule.liste_diagnostic_associe = subview.liste_diagnostic_associe AND
|
|
|
w_budget_cle_rule.liste_acte = subview.liste_acte AND
|
|
|
w_budget_cle_rule.liste_ghm = subview.liste_ghm AND
|
|
|
w_budget_cle_rule.liste_specialite = subview.liste_specialite AND
|
|
|
w_budget_cle_rule.liste_medecin = subview.liste_medecin AND
|
|
|
w_budget_cle_rule.liste_finess = subview.liste_finess AND
|
|
|
w_budget_cle_rule.liste_service = subview.liste_service AND
|
|
|
w_budget_cle_rule.liste_rubrique = subview.liste_rubrique AND
|
|
|
w_budget_cle_rule.liste_sauf_ghm = subview.liste_sauf_ghm AND
|
|
|
w_budget_cle_rule.liste_activite = subview.liste_activite AND
|
|
|
w_budget_cle_rule.liste_type_sejour = subview.liste_type_sejour AND
|
|
|
w_budget_cle_rule.liste_uf = subview.liste_uf AND
|
|
|
w_budget_cle_rule.priorite <> keep_priorite
|
|
|
;
|
|
|
|
|
|
|
|
|
|
|
|
INSERT INTO activite.t_budget_cle_rule (
|
|
|
code,
|
|
|
texte,
|
|
|
budget_cle_id,
|
|
|
priorite,
|
|
|
liste_diagnostic_principal,
|
|
|
liste_diagnostic_relie,
|
|
|
liste_diagnostic_associe,
|
|
|
liste_acte,
|
|
|
liste_ghm,
|
|
|
liste_specialite,
|
|
|
liste_medecin,
|
|
|
liste_finess,
|
|
|
liste_service,
|
|
|
liste_rubrique,
|
|
|
liste_sauf_ghm,
|
|
|
liste_activite,
|
|
|
liste_type_sejour,
|
|
|
liste_uf
|
|
|
)
|
|
|
SELECT
|
|
|
code,
|
|
|
texte,
|
|
|
budget_cle_id,
|
|
|
priorite,
|
|
|
liste_diagnostic_principal,
|
|
|
liste_diagnostic_relie,
|
|
|
liste_diagnostic_associe,
|
|
|
liste_acte,
|
|
|
liste_ghm,
|
|
|
liste_specialite,
|
|
|
liste_medecin,
|
|
|
liste_finess,
|
|
|
liste_service,
|
|
|
liste_rubrique,
|
|
|
liste_sauf_ghm,
|
|
|
liste_activite,
|
|
|
liste_type_sejour,
|
|
|
liste_uf
|
|
|
FROM w_budget_cle_rule
|
|
|
WHERE w_budget_cle_rule.code NOT IN (SELECT code FROM activite.t_budget_cle_rule)
|
|
|
;
|
|
|
|
|
|
UPDATE activite.t_budget_cle_rule SET
|
|
|
texte = w_budget_cle_rule.texte,
|
|
|
budget_cle_id = w_budget_cle_rule.budget_cle_id,
|
|
|
priorite = w_budget_cle_rule.priorite,
|
|
|
liste_diagnostic_principal = w_budget_cle_rule.liste_diagnostic_principal,
|
|
|
liste_diagnostic_relie = w_budget_cle_rule.liste_diagnostic_relie,
|
|
|
liste_diagnostic_associe = w_budget_cle_rule.liste_diagnostic_associe,
|
|
|
liste_acte = w_budget_cle_rule.liste_acte,
|
|
|
liste_ghm = w_budget_cle_rule.liste_ghm,
|
|
|
liste_specialite = w_budget_cle_rule.liste_specialite,
|
|
|
liste_medecin = w_budget_cle_rule.liste_medecin,
|
|
|
liste_finess = w_budget_cle_rule.liste_finess,
|
|
|
liste_service = w_budget_cle_rule.liste_service,
|
|
|
liste_rubrique = w_budget_cle_rule.liste_rubrique,
|
|
|
liste_sauf_ghm = w_budget_cle_rule.liste_sauf_ghm,
|
|
|
liste_activite = w_budget_cle_rule.liste_activite,
|
|
|
liste_type_sejour = w_budget_cle_rule.liste_type_sejour,
|
|
|
liste_uf = w_budget_cle_rule.liste_uf
|
|
|
FROM w_budget_cle_rule
|
|
|
WHERE t_budget_cle_rule.code = w_budget_cle_rule.code AND
|
|
|
(
|
|
|
t_budget_cle_rule.texte IS DISTINCT FROM w_budget_cle_rule.texte OR
|
|
|
t_budget_cle_rule.budget_cle_id IS DISTINCT FROM w_budget_cle_rule.budget_cle_id OR
|
|
|
t_budget_cle_rule.priorite IS DISTINCT FROM w_budget_cle_rule.priorite OR
|
|
|
t_budget_cle_rule.liste_diagnostic_principal IS DISTINCT FROM w_budget_cle_rule.liste_diagnostic_principal OR
|
|
|
t_budget_cle_rule.liste_diagnostic_relie IS DISTINCT FROM w_budget_cle_rule.liste_diagnostic_relie OR
|
|
|
t_budget_cle_rule.liste_diagnostic_associe IS DISTINCT FROM w_budget_cle_rule.liste_diagnostic_associe OR
|
|
|
t_budget_cle_rule.liste_acte IS DISTINCT FROM w_budget_cle_rule.liste_acte OR
|
|
|
t_budget_cle_rule.liste_ghm IS DISTINCT FROM w_budget_cle_rule.liste_ghm OR
|
|
|
t_budget_cle_rule.liste_specialite IS DISTINCT FROM w_budget_cle_rule.liste_specialite OR
|
|
|
t_budget_cle_rule.liste_medecin IS DISTINCT FROM w_budget_cle_rule.liste_medecin OR
|
|
|
t_budget_cle_rule.liste_finess IS DISTINCT FROM w_budget_cle_rule.liste_finess OR
|
|
|
t_budget_cle_rule.liste_service IS DISTINCT FROM w_budget_cle_rule.liste_service OR
|
|
|
t_budget_cle_rule.liste_rubrique IS DISTINCT FROM w_budget_cle_rule.liste_rubrique OR
|
|
|
t_budget_cle_rule.liste_sauf_ghm IS DISTINCT FROM w_budget_cle_rule.liste_sauf_ghm OR
|
|
|
t_budget_cle_rule.liste_activite IS DISTINCT FROM w_budget_cle_rule.liste_activite OR
|
|
|
t_budget_cle_rule.liste_type_sejour IS DISTINCT FROM w_budget_cle_rule.liste_type_sejour OR
|
|
|
t_budget_cle_rule.liste_uf IS DISTINCT FROM w_budget_cle_rule.liste_uf
|
|
|
)
|
|
|
;
|
|
|
|
|
|
DELETE FROM activite.t_budget_cle_rule
|
|
|
WHERE code <> '*ZZ' AND
|
|
|
code NOT IN (SELECT code FROM w_budget_cle_rule) AND
|
|
|
priorite IN (SELECT priorite FROM w_budget_cle_rule)
|
|
|
;
|
|
|
|
|
|
|
|
|
|
|
|
-- Classes par filière
|
|
|
INSERT INTO activite.t_classes(
|
|
|
code, texte, table_id, is_cti, sequence
|
|
|
)
|
|
|
SELECT 'CTI_FIL_BUDG', 'Budget par filière', t_listes_tables.oid, '1', 1
|
|
|
FROM activite.t_listes_tables
|
|
|
JOIN w_budget_settings t_budget ON t_budget.cle_budgetaire_activite IN ('CTIFILMEDSEJ')
|
|
|
LEFT JOIN activite.t_classes ON t_classes.table_id = t_listes_tables.oid
|
|
|
LEFT JOIN activite.t_classes t_classes_s1 ON t_classes_s1.table_id = t_listes_tables.oid AND t_classes_s1.sequence = 1
|
|
|
WHERE t_listes_tables.code = 'BUDGETCLE' AND
|
|
|
t_classes.oid IS NULL AND
|
|
|
t_classes_s1.oid IS NULL
|
|
|
GROUP BY 3
|
|
|
;
|
|
|
|
|
|
-- Classe à alimenter
|
|
|
DROP TABLE IF EXISTS w_classes;
|
|
|
CREATE TEMP TABLE w_classes AS
|
|
|
SELECT
|
|
|
COALESCE((MIN(ARRAY[CASE WHEN t_classes.code = 'CTI_FIL_BUDG' THEN '1' WHEN t_classes.sequence = 1 THEN '2' ELSE '9' END, t_classes.oid::text]))[2]::bigint,0) AS oid
|
|
|
FROM activite.t_classes
|
|
|
JOIN activite.t_listes_tables ON t_classes.table_id = t_listes_tables.oid
|
|
|
WHERE t_listes_tables.code = 'BUDGETCLE'
|
|
|
;
|
|
|
|
|
|
DELETE FROM w_classes
|
|
|
WHERE oid = 0
|
|
|
;
|
|
|
|
|
|
DROP TABLE IF EXISTS w_sections;
|
|
|
CREATE TEMP TABLE w_sections AS
|
|
|
SELECT
|
|
|
t_budget_cle.oid AS budget_cle_id,
|
|
|
MAX(CASE WHEN filiere_soin_id <> 0 THEN filiere_soin_code ELSE '****' END) AS section_code,
|
|
|
MAX(CASE WHEN filiere_soin_id <> 0 THEN filiere_soin_texte ELSE 'SANS FILIERE' END) AS section_texte,
|
|
|
0::bigint AS section_id
|
|
|
FROM w_cle_utilise
|
|
|
JOIN w_budget_settings t_budget ON t_budget.cle_budgetaire_activite IN ('CTIFILMEDSEJ')
|
|
|
JOIN activite.t_budget_cle ON t_budget_cle.code = w_cle_utilise.cle_budget_code
|
|
|
GROUP BY 1
|
|
|
;
|
|
|
|
|
|
INSERT INTO activite.t_classes_sections (code, classe_id, texte)
|
|
|
SELECT section_code, w_classes.oid, MAX(section_texte)
|
|
|
FROM w_classes
|
|
|
JOIN w_sections ON 1=1
|
|
|
LEFT JOIN activite.t_classes_sections ON classe_id = w_classes.oid AND
|
|
|
t_classes_sections.code = w_sections.section_code
|
|
|
WHERE w_classes.oid <> 0 AND t_classes_sections.oid IS NULL
|
|
|
GROUP BY 1,2
|
|
|
ORDER BY 1
|
|
|
;
|
|
|
|
|
|
|
|
|
UPDATE w_sections
|
|
|
SET section_id = t_classes_sections.oid
|
|
|
FROM activite.t_classes_sections
|
|
|
JOIN w_classes ON t_classes_sections.classe_id = w_classes.oid
|
|
|
WHERE section_code = t_classes_sections.code
|
|
|
;
|
|
|
|
|
|
UPDATE activite.t_classes_sections
|
|
|
SET texte = subview.section_texte
|
|
|
FROM
|
|
|
(
|
|
|
SELECT section_id, section_code, w_classes.oid, MAX(section_texte) AS section_texte
|
|
|
FROM w_classes
|
|
|
JOIN w_sections ON 1=1
|
|
|
GROUP BY 1,2,3
|
|
|
ORDER BY 1
|
|
|
) subview
|
|
|
WHERE t_classes_sections.oid = section_id AND
|
|
|
t_classes_sections.texte IS DISTINCT FROM subview.section_texte
|
|
|
;
|
|
|
|
|
|
WITH subview AS
|
|
|
(SELECT section_id, to_id
|
|
|
FROM activite.t_classes_sections_elements
|
|
|
JOIN activite.t_classes_sections ON t_classes_sections_elements.section_id = t_classes_sections.oid
|
|
|
JOIN w_classes ON t_classes_sections.classe_id = w_classes.oid
|
|
|
)
|
|
|
INSERT INTO activite.t_classes_sections_elements
|
|
|
SELECT section_id, budget_cle_id
|
|
|
FROM w_sections
|
|
|
WHERE budget_cle_id NOT IN (SELECT to_id FROM subview)
|
|
|
;
|
|
|
|
|
|
WITH subview AS
|
|
|
(SELECT t_classes_sections_elements.section_id AS section_id, w_sections.section_id AS new_section_id, to_id
|
|
|
FROM activite.t_classes_sections_elements
|
|
|
JOIN activite.t_classes_sections ON t_classes_sections_elements.section_id = t_classes_sections.oid
|
|
|
JOIN w_classes ON t_classes_sections.classe_id = w_classes.oid
|
|
|
JOIN w_sections ON w_sections.budget_cle_id = t_classes_sections_elements.to_id
|
|
|
)
|
|
|
UPDATE activite.t_classes_sections_elements
|
|
|
SET section_id = subview.new_section_id
|
|
|
FROM subview
|
|
|
WHERE subview.to_id = t_classes_sections_elements.to_id AND
|
|
|
subview.section_id = t_classes_sections_elements.section_id AND
|
|
|
t_classes_sections_elements.section_id <> subview.new_section_id
|
|
|
;
|
|
|
|
|
|
-- Suppression des enfants avec clé budgétaire supprimée
|
|
|
DELETE
|
|
|
FROM activite.t_classes_sections_elements
|
|
|
USING activite.t_classes_sections
|
|
|
JOIN w_classes ON classe_id = w_classes.oid
|
|
|
WHERE section_id = t_classes_sections.oid AND
|
|
|
to_id NOT IN (SELECT oid FROM activite.t_budget_cle)
|
|
|
;
|
|
|
|
|
|
-- Suppression des clés sans enfant
|
|
|
DELETE FROM activite.t_classes_sections
|
|
|
WHERE oid IN
|
|
|
(
|
|
|
SELECT t_classes_sections.oid
|
|
|
FROM activite.t_classes_sections
|
|
|
JOIN w_classes ON classe_id = w_classes.oid
|
|
|
WHERE t_classes_sections.oid NOT IN (SELECT section_id FROM activite.t_classes_sections_elements)
|
|
|
)
|
|
|
;
|
|
|
|
|
|
|
|
|
|
|
|
-- Classes par médecin
|
|
|
INSERT INTO activite.t_classes(
|
|
|
code, texte, table_id, is_cti, sequence
|
|
|
)
|
|
|
SELECT 'CTI_MED_BUDG', 'Budget par médecin', t_listes_tables.oid, '1', 2
|
|
|
FROM activite.t_listes_tables
|
|
|
JOIN w_budget_settings t_budget ON t_budget.cle_budgetaire_activite IN ('CTIFILMEDSEJ')
|
|
|
LEFT JOIN activite.t_classes ON t_classes.table_id = t_listes_tables.oid
|
|
|
LEFT JOIN activite.t_classes t_classes_s1 ON t_classes_s1.table_id = t_listes_tables.oid AND t_classes_s1.sequence = 2
|
|
|
WHERE t_listes_tables.code = 'BUDGETCLE' AND
|
|
|
t_classes_s1.oid IS NULL
|
|
|
GROUP BY 3
|
|
|
;
|
|
|
|
|
|
-- Classe à alimenter
|
|
|
DROP TABLE IF EXISTS w_classes;
|
|
|
CREATE TEMP TABLE w_classes AS
|
|
|
SELECT
|
|
|
COALESCE((MIN(ARRAY[CASE WHEN t_classes.code = 'CTI_MED_BUDG' THEN '1' WHEN t_classes.sequence = 2 THEN '2' ELSE '9' END, t_classes.oid::text]))[2]::bigint,0) AS oid
|
|
|
FROM activite.t_classes
|
|
|
JOIN activite.t_listes_tables ON t_classes.table_id = t_listes_tables.oid
|
|
|
WHERE t_listes_tables.code = 'BUDGETCLE'
|
|
|
;
|
|
|
|
|
|
DELETE FROM w_classes
|
|
|
WHERE oid = 0
|
|
|
;
|
|
|
|
|
|
DROP TABLE IF EXISTS w_sections;
|
|
|
CREATE TEMP TABLE w_sections AS
|
|
|
SELECT
|
|
|
t_budget_cle.oid AS budget_cle_id,
|
|
|
MAX(CASE WHEN medecin_id <> 0 THEN medecin_code ELSE '****' END) AS section_code,
|
|
|
MAX(CASE WHEN medecin_id <> 0 THEN medecin_texte ELSE 'SANS FILIERE' END) AS section_texte,
|
|
|
0::bigint AS section_id
|
|
|
FROM w_cle_utilise
|
|
|
JOIN w_budget_settings t_budget ON t_budget.cle_budgetaire_activite IN ('CTIFILMEDSEJ')
|
|
|
JOIN activite.t_budget_cle ON t_budget_cle.code = w_cle_utilise.cle_budget_code
|
|
|
WHERE medecin_id <> 0
|
|
|
GROUP BY 1
|
|
|
;
|
|
|
|
|
|
INSERT INTO activite.t_classes_sections (code, classe_id, texte)
|
|
|
SELECT section_code, w_classes.oid, MAX(section_texte)
|
|
|
FROM w_classes
|
|
|
JOIN w_sections ON 1=1
|
|
|
LEFT JOIN activite.t_classes_sections ON classe_id = w_classes.oid AND
|
|
|
t_classes_sections.code = w_sections.section_code
|
|
|
WHERE w_classes.oid <> 0 AND t_classes_sections.oid IS NULL
|
|
|
GROUP BY 1,2
|
|
|
ORDER BY 1
|
|
|
;
|
|
|
|
|
|
|
|
|
UPDATE w_sections
|
|
|
SET section_id = t_classes_sections.oid
|
|
|
FROM activite.t_classes_sections
|
|
|
JOIN w_classes ON t_classes_sections.classe_id = w_classes.oid
|
|
|
WHERE section_code = t_classes_sections.code
|
|
|
;
|
|
|
|
|
|
UPDATE activite.t_classes_sections
|
|
|
SET texte = subview.section_texte
|
|
|
FROM
|
|
|
(
|
|
|
SELECT section_id, section_code, w_classes.oid, MAX(section_texte) AS section_texte
|
|
|
FROM w_classes
|
|
|
JOIN w_sections ON 1=1
|
|
|
GROUP BY 1,2,3
|
|
|
ORDER BY 1
|
|
|
) subview
|
|
|
WHERE t_classes_sections.oid = section_id AND
|
|
|
t_classes_sections.texte IS DISTINCT FROM subview.section_texte
|
|
|
;
|
|
|
|
|
|
WITH subview AS
|
|
|
(SELECT section_id, to_id
|
|
|
FROM activite.t_classes_sections_elements
|
|
|
JOIN activite.t_classes_sections ON t_classes_sections_elements.section_id = t_classes_sections.oid
|
|
|
JOIN w_classes ON t_classes_sections.classe_id = w_classes.oid
|
|
|
)
|
|
|
INSERT INTO activite.t_classes_sections_elements
|
|
|
SELECT section_id, budget_cle_id
|
|
|
FROM w_sections
|
|
|
WHERE budget_cle_id NOT IN (SELECT to_id FROM subview)
|
|
|
;
|
|
|
|
|
|
WITH subview AS
|
|
|
(SELECT t_classes_sections_elements.section_id AS section_id, w_sections.section_id AS new_section_id, to_id
|
|
|
FROM activite.t_classes_sections_elements
|
|
|
JOIN activite.t_classes_sections ON t_classes_sections_elements.section_id = t_classes_sections.oid
|
|
|
JOIN w_classes ON t_classes_sections.classe_id = w_classes.oid
|
|
|
JOIN w_sections ON w_sections.budget_cle_id = t_classes_sections_elements.to_id
|
|
|
)
|
|
|
UPDATE activite.t_classes_sections_elements
|
|
|
SET section_id = subview.new_section_id
|
|
|
FROM subview
|
|
|
WHERE subview.to_id = t_classes_sections_elements.to_id AND
|
|
|
subview.section_id = t_classes_sections_elements.section_id AND
|
|
|
t_classes_sections_elements.section_id <> subview.new_section_id
|
|
|
;
|
|
|
|
|
|
-- Suppression des enfants avec clé budgétaire supprimée
|
|
|
DELETE
|
|
|
FROM activite.t_classes_sections_elements
|
|
|
USING activite.t_classes_sections
|
|
|
JOIN w_classes ON classe_id = w_classes.oid
|
|
|
WHERE section_id = t_classes_sections.oid AND
|
|
|
to_id NOT IN (SELECT oid FROM activite.t_budget_cle)
|
|
|
;
|
|
|
|
|
|
-- Suppression des clés sans enfant
|
|
|
DELETE FROM activite.t_classes_sections
|
|
|
WHERE oid IN
|
|
|
(
|
|
|
SELECT t_classes_sections.oid
|
|
|
FROM activite.t_classes_sections
|
|
|
JOIN w_classes ON classe_id = w_classes.oid
|
|
|
WHERE t_classes_sections.oid NOT IN (SELECT section_id FROM activite.t_classes_sections_elements)
|
|
|
)
|
|
|
;
|
|
|
|
|
|
PERFORM base.cti_update_classes('activite', 't_budget_cle', 'BUDGETCLE','');
|
|
|
PERFORM activite.cti_reorganize_indicateur_condition();
|
|
|
|
|
|
END IF;
|
|
|
|
|
|
PERFORM activite.cti_reorganize_indicateur_condition()
|
|
|
;
|
|
|
|
|
|
-- Génération des indicateurs de budget (CTI)
|
|
|
IF EXISTS (SELECT * FROM w_budget_settings WHERE cle_budgetaire_activite IN ('CTIMEDSEJ')) THEN
|
|
|
DROP SEQUENCE IF EXISTS w_indicateur_budget_sequence;
|
|
|
CREATE TEMP SEQUENCE w_indicateur_budget_sequence;
|
|
|
|
|
|
DROP TABLE IF EXISTS w_indicateurs_budget;
|
|
|
CREATE TEMP TABLE w_indicateurs_budget AS
|
|
|
SELECT
|
|
|
'CTI_BUD_MT_RUBMED_HOAM_MCO_FAVA' AS code, 'Budget. CA Séjour Facturé + Valorisé MCO [HOSP + AMBU]' AS texte,'CA Séjour F+V [H+A]' AS entete, 'CA Séjour Facturé + Valorisé MCO [HOSP + AMBU]' AS entete_etendue, '#' AS output_format,
|
|
|
'FACTURATION_CLINIQUE' AS table_name,
|
|
|
'CASE WHEN rubrique_facturation_id IN [LISTE:CTI_RUBMED_R] AND type_sejour IN (''1'',''2'') AND forme_activite_section_code[2] in (''11'',''12'',''13'',''19'') THEN montant_facture + montant_encours ELSE 0 END' AS column_name,
|
|
|
'SUM' AS total_function,
|
|
|
'1' AS dimension_date_1,
|
|
|
'2' AS dimension_date_2,
|
|
|
'3' AS dimension_date_3,
|
|
|
'4' AS dimension_date_4,
|
|
|
'' AS dimension_date_5,
|
|
|
'1' AS is_cti,
|
|
|
nextval('w_indicateur_budget_sequence'::regclass) AS numero,
|
|
|
'MTSEJMCO'::text AS indicateur_budget_code,
|
|
|
'CA Séjour MCO (HC+HJ)'::text AS indicateur_budget_texte,
|
|
|
'CTI_BUD_MT_RUBMED_HOAM_MCO_FAVA#1' AS indicateur_code,
|
|
|
'01'::text AS rapport_chapitre_code,
|
|
|
'CA Séjour'::text AS rapport_chapitre_texte
|
|
|
UNION
|
|
|
SELECT
|
|
|
'CTI_BUD_EMC_HOAM_MCO' AS code, 'Budget. EMC [Hosp + ambu] MCO' AS texte,'EMC MCO' AS entete, 'EMC hosp et ambu MCO' AS entete_etendue, '#' AS output_format,
|
|
|
'OCCUPATION' AS table_name,
|
|
|
'CASE WHEN type_sejour IN (''1'',''2'') AND forme_activite_section_code[2] IN (''11'',''12'',''13'',''19'') THEN equivalent_malade_complet ELSE 0 END' AS column_name,
|
|
|
'SUM' AS total_function,
|
|
|
'1' AS dimension_date_1,
|
|
|
'' AS dimension_date_2,
|
|
|
'' AS dimension_date_3,
|
|
|
'' AS dimension_date_4,
|
|
|
'' AS dimension_date_5,
|
|
|
'1' AS is_cti,
|
|
|
nextval('w_indicateur_budget_sequence'::regclass) AS numero,
|
|
|
'EMCMCO'::text AS indicateur_budget_code,
|
|
|
'EMC MCO (HC+HJ)'::text AS indicateur_budget_texte,
|
|
|
'CTI_BUD_EMC_HOAM_MCO' AS indicateur_code,
|
|
|
'01'::text AS rapport_chapitre_code,
|
|
|
'CA Séjour'::text AS rapport_chapitre_texte
|
|
|
UNION
|
|
|
SELECT
|
|
|
'CTI_BUD_GHSM_HOAM_MCO' AS code, 'Budget. GHS Moyen [Hosp + ambu] MCO' AS texte,'GHS Moyen' AS entete, 'GHS Moyen hosp et ambu' AS entete_etendue, '#' AS output_format,
|
|
|
'*CALC' AS table_name,
|
|
|
'base.cti_division([1], [2])' AS column_name,
|
|
|
'SUM' AS total_function,
|
|
|
'' AS dimension_date_1,
|
|
|
'' AS dimension_date_2,
|
|
|
'' AS dimension_date_3,
|
|
|
'' AS dimension_date_4,
|
|
|
'' AS dimension_date_5,
|
|
|
'1' AS is_cti,
|
|
|
nextval('w_indicateur_budget_sequence'::regclass) AS numero,
|
|
|
'GHSMMCO'::text AS indicateur_budget_code,
|
|
|
'GHS Moyen MCO (HC+HJ)'::text AS indicateur_budget_texte,
|
|
|
'CTI_BUD_GHSM_HOAM_MCO' AS indicateur_code,
|
|
|
'01'::text AS rapport_chapitre_code,
|
|
|
'CA Séjour'::text AS rapport_chapitre_texte
|
|
|
UNION
|
|
|
SELECT
|
|
|
'CTI_BUD_JOU_HOAM_MCO' AS code, 'Budget. Nombre de jours [Hosp + ambu] MCO' AS texte,'Jours MCO' AS entete, 'Jours hosp et ambu MCO' AS entete_etendue, '#' AS output_format,
|
|
|
'OCCUPATION' AS table_name,
|
|
|
'CASE WHEN type_sejour IN (''1'',''2'') AND forme_activite_section_code[2] IN (''11'',''12'',''13'',''19'') THEN nb_jours_f + nb_ambulatoires ELSE 0 END' AS column_name,
|
|
|
'SUM' AS total_function,
|
|
|
'1' AS dimension_date_1,
|
|
|
'' AS dimension_date_2,
|
|
|
'' AS dimension_date_3,
|
|
|
'' AS dimension_date_4,
|
|
|
'' AS dimension_date_5,
|
|
|
'1' AS is_cti,
|
|
|
nextval('w_indicateur_budget_sequence'::regclass) AS numero,
|
|
|
'JOUMCO'::text AS indicateur_budget_code,
|
|
|
'Jours MCO (HC+HJ)'::text AS indicateur_budget_texte,
|
|
|
'CTI_BUD_JOU_HOAM_MCO' AS indicateur_code,
|
|
|
'01'::text AS rapport_chapitre_code,
|
|
|
'CA Séjour'::text AS rapport_chapitre_texte
|
|
|
UNION
|
|
|
SELECT
|
|
|
'CTI_BUD_MT_REA_FAVA' AS code, 'Budget. CA REA Facturé + Valorisé' AS texte,'Montant REA F+V' AS entete, 'Montant REA facturé + valorisé' AS entete_etendue, '#E' AS output_format,
|
|
|
'FACTURATION_CLINIQUE' AS table_name,
|
|
|
'CASE WHEN prestation_code IN (''REA'') THEN montant_facture+montant_encours ELSE 0 END' AS column_name,
|
|
|
'SUM' AS total_function,
|
|
|
'1' AS dimension_date_1,
|
|
|
'2' AS dimension_date_2,
|
|
|
'3' AS dimension_date_3,
|
|
|
'4' AS dimension_date_4,
|
|
|
'' AS dimension_date_5,
|
|
|
'1' AS is_cti,
|
|
|
nextval('w_indicateur_budget_sequence'::regclass) AS numero,
|
|
|
'MTREA'::text AS indicateur_budget_code,
|
|
|
'CA REA'::text AS indicateur_budget_texte,
|
|
|
'CTI_BUD_MT_REA_FAVA#1' AS indicateur_code,
|
|
|
'02'::text AS rapport_chapitre_code,
|
|
|
'CA Suppléments'::text AS rapport_chapitre_texte
|
|
|
UNION
|
|
|
SELECT
|
|
|
'CTI_BUD_MT_STF_FAVA' AS code, 'Budget. CA STF Facturé + Valorisé' AS texte,'Montant STF F+V' AS entete, 'Montant STF facturé + valorisé' AS entete_etendue, '#E' AS output_format,
|
|
|
'FACTURATION_CLINIQUE' AS table_name,
|
|
|
'CASE WHEN prestation_code IN (''STF'') THEN montant_facture+montant_encours ELSE 0 END' AS column_name,
|
|
|
'SUM' AS total_function,
|
|
|
'1' AS dimension_date_1,
|
|
|
'2' AS dimension_date_2,
|
|
|
'3' AS dimension_date_3,
|
|
|
'4' AS dimension_date_4,
|
|
|
'' AS dimension_date_5,
|
|
|
'1' AS is_cti,
|
|
|
nextval('w_indicateur_budget_sequence'::regclass) AS numero,
|
|
|
'MTSTF'::text AS indicateur_budget_code,
|
|
|
'CA STF'::text AS indicateur_budget_texte,
|
|
|
'CTI_BUD_MT_STF_FAVA#1' AS indicateur_code,
|
|
|
'02'::text AS rapport_chapitre_code,
|
|
|
'CA Suppléments'::text AS rapport_chapitre_texte
|
|
|
UNION
|
|
|
SELECT
|
|
|
'CTI_BUD_MT_SRC_FAVA' AS code, 'Budget. CA SRC Facturé + Valorisé' AS texte,'Montant SRC F+V' AS entete, 'Montant SRC facturé + valorisé' AS entete_etendue, '#E' AS output_format,
|
|
|
'FACTURATION_CLINIQUE' AS table_name,
|
|
|
'CASE WHEN prestation_code IN (''SRC'', ''SSC'') THEN montant_facture+montant_encours ELSE 0 END' AS column_name,
|
|
|
'SUM' AS total_function,
|
|
|
'1' AS dimension_date_1,
|
|
|
'2' AS dimension_date_2,
|
|
|
'3' AS dimension_date_3,
|
|
|
'4' AS dimension_date_4,
|
|
|
'' AS dimension_date_5,
|
|
|
'1' AS is_cti,
|
|
|
nextval('w_indicateur_budget_sequence'::regclass) AS numero,
|
|
|
'MTSRC'::text AS indicateur_budget_code,
|
|
|
'CA SRC'::text AS indicateur_budget_texte,
|
|
|
'CTI_BUD_MT_SRC_FAVA#1' AS indicateur_code,
|
|
|
'02'::text AS rapport_chapitre_code,
|
|
|
'CA Suppléments'::text AS rapport_chapitre_texte
|
|
|
UNION
|
|
|
SELECT
|
|
|
'CTI_BUD_MT_NNN_FAVA' AS code, 'Budget. CA NNN Facturé + Valorisé' AS texte,'Montant NNN F+V' AS entete, 'Montant NNN facturé + valorisé' AS entete_etendue, '#E' AS output_format,
|
|
|
'FACTURATION_CLINIQUE' AS table_name,
|
|
|
'CASE WHEN prestation_code IN (''NN1'',''NN3'',''NN2'') THEN montant_facture+montant_encours ELSE 0 END' AS column_name,
|
|
|
'SUM' AS total_function,
|
|
|
'1' AS dimension_date_1,
|
|
|
'2' AS dimension_date_2,
|
|
|
'3' AS dimension_date_3,
|
|
|
'4' AS dimension_date_4,
|
|
|
'' AS dimension_date_5,
|
|
|
'1' AS is_cti,
|
|
|
nextval('w_indicateur_budget_sequence'::regclass) AS numero,
|
|
|
'MTNNN'::text AS indicateur_budget_code,
|
|
|
'CA NN'::text AS indicateur_budget_texte,
|
|
|
'CTI_BUD_MT_NNN_FAVA#1' AS indicateur_code,
|
|
|
'02'::text AS rapport_chapitre_code,
|
|
|
'CA Suppléments'::text AS rapport_chapitre_texte
|
|
|
UNION
|
|
|
SELECT
|
|
|
'CTI_BUD_MT_RUBMED_CHM_MCO_FAVA' AS code, 'Budget. CA Chimio Facturé + Valorisé' AS texte,'Montant CHM F+V' AS entete, 'Montant Chimio facturé + valorisé' AS entete_etendue, '#E' AS output_format,
|
|
|
'FACTURATION_CLINIQUE' AS table_name,
|
|
|
'CASE WHEN rubrique_facturation_id IN [LISTE:CTI_RUBMED_R] AND type_sejour = ''5'' AND forme_activite_code = ''132'' THEN montant_facture + montant_encours ELSE 0 END' AS column_name,
|
|
|
'SUM' AS total_function,
|
|
|
'1' AS dimension_date_1,
|
|
|
'2' AS dimension_date_2,
|
|
|
'3' AS dimension_date_3,
|
|
|
'4' AS dimension_date_4,
|
|
|
'' AS dimension_date_5,
|
|
|
'1' AS is_cti,
|
|
|
nextval('w_indicateur_budget_sequence'::regclass) AS numero,
|
|
|
'MTSEJCHM'::text AS indicateur_budget_code,
|
|
|
'CA Chimio'::text AS indicateur_budget_texte,
|
|
|
'CTI_BUD_MT_RUBMED_CHM_MCO_FAVA#1' AS indicateur_code,
|
|
|
'01'::text AS rapport_chapitre_code,
|
|
|
'CA Séjour'::text AS rapport_chapitre_texte
|
|
|
UNION
|
|
|
SELECT
|
|
|
'CTI_BUD_MT_RUBMED_DIA_MCO_FAVA' AS code, 'Budget. CA Dialyse Facturé + Valorisé' AS texte,'Montant DIA F+V' AS entete, 'Montant Dialyse facturé + valorisé' AS entete_etendue, '#E' AS output_format,
|
|
|
'FACTURATION_CLINIQUE' AS table_name,
|
|
|
'CASE WHEN rubrique_facturation_id IN [LISTE:CTI_RUBMED_R] AND type_sejour = ''5'' AND forme_activite_code = ''131'' THEN montant_facture + montant_encours ELSE 0 END' AS column_name,
|
|
|
'SUM' AS total_function,
|
|
|
'1' AS dimension_date_1,
|
|
|
'2' AS dimension_date_2,
|
|
|
'3' AS dimension_date_3,
|
|
|
'4' AS dimension_date_4,
|
|
|
'' AS dimension_date_5,
|
|
|
'1' AS is_cti,
|
|
|
nextval('w_indicateur_budget_sequence'::regclass) AS numero,
|
|
|
'MTSEJDIA'::text AS indicateur_budget_code,
|
|
|
'CA Dialyse'::text AS indicateur_budget_texte,
|
|
|
'CTI_BUD_MT_RUBMED_DIA_MCO_FAVA#1' AS indicateur_code,
|
|
|
'01'::text AS rapport_chapitre_code,
|
|
|
'CA Séjour'::text AS rapport_chapitre_texte
|
|
|
UNION
|
|
|
SELECT
|
|
|
'CTI_BUD_MT_EST_FAVA' AS code, 'Budget. CA Esthétique Facturé + Valorisé' AS texte,'Montant ESTH F+V' AS entete, 'Montant Esthétique facturé + valorisé' AS entete_etendue, '#E' AS output_format,
|
|
|
'FACTURATION_CLINIQUE' AS table_name,
|
|
|
'CASE WHEN rubrique_facturation_id IN [LISTE:CTI_T2A_R] AND forme_activite_section_code[1] = ''1'' AND forme_activite_section_code[2] = ''14'' THEN montant_facture + montant_encours ELSE 0 END' AS column_name,
|
|
|
'SUM' AS total_function,
|
|
|
'1' AS dimension_date_1,
|
|
|
'2' AS dimension_date_2,
|
|
|
'3' AS dimension_date_3,
|
|
|
'4' AS dimension_date_4,
|
|
|
'' AS dimension_date_5,
|
|
|
'1' AS is_cti,
|
|
|
nextval('w_indicateur_budget_sequence'::regclass) AS numero,
|
|
|
'MTEST'::text AS indicateur_budget_code,
|
|
|
'CA Esthétique'::text AS indicateur_budget_texte,
|
|
|
'CTI_BUD_MT_EST_FAVA#1' AS indicateur_code,
|
|
|
'01'::text AS rapport_chapitre_code,
|
|
|
'CA Séjour'::text AS rapport_chapitre_texte
|
|
|
UNION
|
|
|
SELECT
|
|
|
'CTI_BUD_MT_RUBMED_SSR_FAVA' AS code, 'Budget. CA SSR Facturé + Valorisé' AS texte,'Montant SSR F+V' AS entete, 'Montant SSR facturé + valorisé' AS entete_etendue, '#E' AS output_format,
|
|
|
'FACTURATION_CLINIQUE' AS table_name,
|
|
|
'CASE WHEN rubrique_facturation_id IN [LISTE:CTI_RUBMED_R] AND forme_activite_section_code[1] = ''2'' THEN montant_facture + montant_encours ELSE 0 END' AS column_name,
|
|
|
'SUM' AS total_function,
|
|
|
'1' AS dimension_date_1,
|
|
|
'2' AS dimension_date_2,
|
|
|
'3' AS dimension_date_3,
|
|
|
'4' AS dimension_date_4,
|
|
|
'' AS dimension_date_5,
|
|
|
'1' AS is_cti,
|
|
|
nextval('w_indicateur_budget_sequence'::regclass) AS numero,
|
|
|
'MTSEJSSR'::text AS indicateur_budget_code,
|
|
|
'CA SSR'::text AS indicateur_budget_texte,
|
|
|
'CTI_BUD_MT_RUBMED_SSR_FAVA#1' AS indicateur_code,
|
|
|
'01'::text AS rapport_chapitre_code,
|
|
|
'CA Séjour'::text AS rapport_chapitre_texte
|
|
|
UNION
|
|
|
SELECT
|
|
|
'CTI_BUD_JOU_SSR' AS code, 'Budget. Nombre de jours SSR' AS texte,'Jours SSR' AS entete, 'Jours SSR' AS entete_etendue, '#' AS output_format,
|
|
|
'OCCUPATION' AS table_name,
|
|
|
'CASE WHEN forme_activite_section_code[1] = ''3'' THEN nb_jours_f + nb_ambulatoires ELSE 0 END' AS column_name,
|
|
|
'SUM' AS total_function,
|
|
|
'1' AS dimension_date_1,
|
|
|
'' AS dimension_date_2,
|
|
|
'' AS dimension_date_3,
|
|
|
'' AS dimension_date_4,
|
|
|
'' AS dimension_date_5,
|
|
|
'1' AS is_cti,
|
|
|
nextval('w_indicateur_budget_sequence'::regclass) AS numero,
|
|
|
'JOUSSR'::text AS indicateur_budget_code,
|
|
|
'Jours SSR'::text AS indicateur_budget_texte,
|
|
|
'CTI_BUD_JOU_SSR' AS indicateur_code,
|
|
|
'01'::text AS rapport_chapitre_code,
|
|
|
'CA Séjour'::text AS rapport_chapitre_texte
|
|
|
UNION
|
|
|
SELECT
|
|
|
'CTI_BUD_MT_RUBMED_PSY_FAVA' AS code, 'Budget. CA PSY Facturé + Valorisé' AS texte,'Montant PSY F+V' AS entete, 'Montant PSY facturé + valorisé' AS entete_etendue, '#E' AS output_format,
|
|
|
'FACTURATION_CLINIQUE' AS table_name,
|
|
|
'CASE WHEN rubrique_facturation_id IN [LISTE:CTI_RUBMED_R] AND forme_activite_section_code[1] = ''3'' THEN montant_facture + montant_encours ELSE 0 END' AS column_name,
|
|
|
'SUM' AS total_function,
|
|
|
'1' AS dimension_date_1,
|
|
|
'2' AS dimension_date_2,
|
|
|
'3' AS dimension_date_3,
|
|
|
'4' AS dimension_date_4,
|
|
|
'' AS dimension_date_5,
|
|
|
'1' AS is_cti,
|
|
|
nextval('w_indicateur_budget_sequence'::regclass) AS numero,
|
|
|
'MTSEJPSY'::text AS indicateur_budget_code,
|
|
|
'CA PSY'::text AS indicateur_budget_texte,
|
|
|
'CTI_BUD_MT_RUBMED_PSY_FAVA#1' AS indicateur_code,
|
|
|
'01'::text AS rapport_chapitre_code,
|
|
|
'CA Séjour'::text AS rapport_chapitre_texte
|
|
|
UNION
|
|
|
SELECT
|
|
|
'CTI_BUD_JOU_PSY' AS code, 'Budget. Nombre de jours PSY' AS texte,'Jours PSY' AS entete, 'Jours PSY' AS entete_etendue, '#' AS output_format,
|
|
|
'OCCUPATION' AS table_name,
|
|
|
'CASE WHEN forme_activite_section_code[1] = ''3'' THEN nb_jours_f + nb_ambulatoires ELSE 0 END' AS column_name,
|
|
|
'SUM' AS total_function,
|
|
|
'1' AS dimension_date_1,
|
|
|
'' AS dimension_date_2,
|
|
|
'' AS dimension_date_3,
|
|
|
'' AS dimension_date_4,
|
|
|
'' AS dimension_date_5,
|
|
|
'1' AS is_cti,
|
|
|
nextval('w_indicateur_budget_sequence'::regclass) AS numero,
|
|
|
'JOUPSY'::text AS indicateur_budget_code,
|
|
|
'Jours PSY'::text AS indicateur_budget_texte,
|
|
|
'CTI_BUD_JOU_PSY' AS indicateur_code,
|
|
|
'01'::text AS rapport_chapitre_code,
|
|
|
'CA Séjour'::text AS rapport_chapitre_texte
|
|
|
UNION
|
|
|
SELECT
|
|
|
'CTI_BUD_MT_RUBMED_HAD_FAVA' AS code, 'Budget. CA HAD Facturé + Valorisé' AS texte,'Montant HAD F+V' AS entete, 'Montant HAD facturé + valorisé' AS entete_etendue, '#E' AS output_format,
|
|
|
'FACTURATION_CLINIQUE' AS table_name,
|
|
|
'CASE WHEN rubrique_facturation_id IN [LISTE:CTI_RUBMED_R] AND forme_activite_section_code[1] = ''4'' THEN montant_facture + montant_encours ELSE 0 END' AS column_name,
|
|
|
'SUM' AS total_function,
|
|
|
'1' AS dimension_date_1,
|
|
|
'2' AS dimension_date_2,
|
|
|
'3' AS dimension_date_3,
|
|
|
'4' AS dimension_date_4,
|
|
|
'' AS dimension_date_5,
|
|
|
'1' AS is_cti,
|
|
|
nextval('w_indicateur_budget_sequence'::regclass) AS numero,
|
|
|
'MTHAD'::text AS indicateur_budget_code,
|
|
|
'CA HAD'::text AS indicateur_budget_texte,
|
|
|
'CTI_BUD_MT_RUBMED_HAD_FAVA#1' AS indicateur_code,
|
|
|
'01'::text AS rapport_chapitre_code,
|
|
|
'CA Séjour'::text AS rapport_chapitre_texte
|
|
|
UNION
|
|
|
SELECT
|
|
|
'CTI_BUD_MT_IVG_FAVA' AS code, 'Budget. CA IVG Facturé + Valorisé' AS texte,'Montant IVG F+V' AS entete, 'Montant IVG facturé + valorisé' AS entete_etendue, '#E' AS output_format,
|
|
|
'FACTURATION_CLINIQUE' AS table_name,
|
|
|
'CASE WHEN rubrique_facturation_id IN [LISTE:CTI_IVG_R] THEN montant_facture + montant_encours ELSE 0 END' AS column_name,
|
|
|
'SUM' AS total_function,
|
|
|
'1' AS dimension_date_1,
|
|
|
'2' AS dimension_date_2,
|
|
|
'3' AS dimension_date_3,
|
|
|
'4' AS dimension_date_4,
|
|
|
'' AS dimension_date_5,
|
|
|
'1' AS is_cti,
|
|
|
nextval('w_indicateur_budget_sequence'::regclass) AS numero,
|
|
|
'MTIVG'::text AS indicateur_budget_code,
|
|
|
'CA IVG'::text AS indicateur_budget_texte,
|
|
|
'CTI_BUD_MT_IVG_FAVA#1' AS indicateur_code,
|
|
|
'01'::text AS rapport_chapitre_code,
|
|
|
'CA Séjour'::text AS rapport_chapitre_texte
|
|
|
UNION
|
|
|
SELECT
|
|
|
'CTI_BUD_MT_CPC_FAVA' AS code, 'Budget. CA CPC Facturé + Valorisé' AS texte,'Montant CPC F+V' AS entete, 'Montant CPC facturé + valorisé' AS entete_etendue, '#E' AS output_format,
|
|
|
'FACTURATION_CLINIQUE' AS table_name,
|
|
|
'CASE WHEN rubrique_facturation_id IN [LISTE:CTI_SHO_R] THEN montant_facture + montant_encours ELSE 0 END' AS column_name,
|
|
|
'SUM' AS total_function,
|
|
|
'1' AS dimension_date_1,
|
|
|
'2' AS dimension_date_2,
|
|
|
'3' AS dimension_date_3,
|
|
|
'4' AS dimension_date_4,
|
|
|
'' AS dimension_date_5,
|
|
|
'1' AS is_cti,
|
|
|
nextval('w_indicateur_budget_sequence'::regclass) AS numero,
|
|
|
'MTCPC'::text AS indicateur_budget_code,
|
|
|
'CA CPC'::text AS indicateur_budget_texte,
|
|
|
'CTI_BUD_MT_CPC_FAVA#1' AS indicateur_code,
|
|
|
'03'::text AS rapport_chapitre_code,
|
|
|
'CA Chambres particulières'::text AS rapport_chapitre_texte
|
|
|
UNION
|
|
|
SELECT
|
|
|
'CTI_BUD_MT_FSE_FAVA' AS code, 'Budget. CA FSE Facturé + Valorisé' AS texte,'Montant FSE F+V' AS entete, 'Montant FSE facturé + valorisé' AS entete_etendue, '#E' AS output_format,
|
|
|
'FACTURATION_CLINIQUE' AS table_name,
|
|
|
'CASE WHEN rubrique_facturation_id IN [LISTE:CTI_SE_R] THEN montant_facture + montant_encours ELSE NULL END' AS column_name,
|
|
|
'SUM' AS total_function,
|
|
|
'1' AS dimension_date_1,
|
|
|
'2' AS dimension_date_2,
|
|
|
'3' AS dimension_date_3,
|
|
|
'4' AS dimension_date_4,
|
|
|
'' AS dimension_date_5,
|
|
|
'1' AS is_cti,
|
|
|
nextval('w_indicateur_budget_sequence'::regclass) AS numero,
|
|
|
'MTFSE'::text AS indicateur_budget_code,
|
|
|
'CA SE'::text AS indicateur_budget_texte,
|
|
|
'CTI_BUD_MT_FSE_FAVA#1' AS indicateur_code,
|
|
|
'04'::text AS rapport_chapitre_code,
|
|
|
'Externes et divers'::text AS rapport_chapitre_texte
|
|
|
UNION
|
|
|
SELECT
|
|
|
'CTI_BUD_MT_ATU_FAVA' AS code, 'Budget. CA ATU Facturé + Valorisé' AS texte,'Montant ATU F+V' AS entete, 'Montant ATU facturé + valorisé' AS entete_etendue, '#E' AS output_format,
|
|
|
'FACTURATION_CLINIQUE' AS table_name,
|
|
|
'CASE WHEN prestation_code IN (''ATU'',''FPU'') THEN montant_facture+montant_encours ELSE 0 END' AS column_name,
|
|
|
'SUM' AS total_function,
|
|
|
'1' AS dimension_date_1,
|
|
|
'2' AS dimension_date_2,
|
|
|
'3' AS dimension_date_3,
|
|
|
'4' AS dimension_date_4,
|
|
|
'' AS dimension_date_5,
|
|
|
'1' AS is_cti,
|
|
|
nextval('w_indicateur_budget_sequence'::regclass) AS numero,
|
|
|
'MTATU'::text AS indicateur_budget_code,
|
|
|
'CA ATU'::text AS indicateur_budget_texte,
|
|
|
'CTI_BUD_MT_ATU_FAVA#1' AS indicateur_code,
|
|
|
'04'::text AS rapport_chapitre_code,
|
|
|
'Externes et divers'::text AS rapport_chapitre_texte
|
|
|
UNION
|
|
|
SELECT
|
|
|
'CTI_BUD_MT_FFM_FAVA' AS code, 'Budget. CA FFM Facturé + Valorisé' AS texte,'Montant FFM F+V' AS entete, 'Montant FFM facturé + valorisé' AS entete_etendue, '#E' AS output_format,
|
|
|
'FACTURATION_CLINIQUE' AS table_name,
|
|
|
'CASE WHEN prestation_code IN (''FFM'') THEN montant_facture+montant_encours ELSE 0 END' AS column_name,
|
|
|
'SUM' AS total_function,
|
|
|
'1' AS dimension_date_1,
|
|
|
'2' AS dimension_date_2,
|
|
|
'3' AS dimension_date_3,
|
|
|
'4' AS dimension_date_4,
|
|
|
'' AS dimension_date_5,
|
|
|
'1' AS is_cti,
|
|
|
nextval('w_indicateur_budget_sequence'::regclass) AS numero,
|
|
|
'MTFFM'::text AS indicateur_budget_code,
|
|
|
'CA FFM'::text AS indicateur_budget_texte,
|
|
|
'CTI_BUD_MT_FFM_FAVA#1' AS indicateur_code,
|
|
|
'04'::text AS rapport_chapitre_code,
|
|
|
'Externes et divers'::text AS rapport_chapitre_texte
|
|
|
UNION
|
|
|
SELECT
|
|
|
'CTI_BUD_MT_FSD_FAVA' AS code, 'Budget. CA FSD Facturé + Valorisé' AS texte,'Montant FSD F+V' AS entete, 'Montant FSD facturé + valorisé' AS entete_etendue, '#E' AS output_format,
|
|
|
'FACTURATION_CLINIQUE' AS table_name,
|
|
|
'CASE WHEN prestation_code IN (''FSD'') THEN montant_comptabilise+montant_encours ELSE 0 END' AS column_name,
|
|
|
'SUM' AS total_function,
|
|
|
'1' AS dimension_date_1,
|
|
|
'2' AS dimension_date_2,
|
|
|
'3' AS dimension_date_3,
|
|
|
'4' AS dimension_date_4,
|
|
|
'' AS dimension_date_5,
|
|
|
'1' AS is_cti,
|
|
|
nextval('w_indicateur_budget_sequence'::regclass) AS numero,
|
|
|
'MTFSD'::text AS indicateur_budget_code,
|
|
|
'CA FSD'::text AS indicateur_budget_texte,
|
|
|
'CTI_BUD_MT_FSD_FAVA#1' AS indicateur_code,
|
|
|
'04'::text AS rapport_chapitre_code,
|
|
|
'Externes et divers'::text AS rapport_chapitre_texte
|
|
|
UNION
|
|
|
SELECT
|
|
|
'CTI_BUD_MT_ETI_FAVA' AS code, 'Budget. CA ETI Facturé + Valorisé' AS texte,'Montant ETI F+V' AS entete, 'Montant ETI facturé + valorisé' AS entete_etendue, '#E' AS output_format,
|
|
|
'FACTURATION_CLINIQUE' AS table_name,
|
|
|
'CASE WHEN prestation_code IN (''ETI'') THEN montant_facture+montant_encours ELSE 0 END' AS column_name,
|
|
|
'SUM' AS total_function,
|
|
|
'1' AS dimension_date_1,
|
|
|
'2' AS dimension_date_2,
|
|
|
'3' AS dimension_date_3,
|
|
|
'4' AS dimension_date_4,
|
|
|
'' AS dimension_date_5,
|
|
|
'1' AS is_cti,
|
|
|
nextval('w_indicateur_budget_sequence'::regclass) AS numero,
|
|
|
'MTETI'::text AS indicateur_budget_code,
|
|
|
'CA ETI'::text AS indicateur_budget_texte,
|
|
|
'CTI_BUD_MT_ETI_FAVA#1' AS indicateur_code,
|
|
|
'04'::text AS rapport_chapitre_code,
|
|
|
'Externes et divers'::text AS rapport_chapitre_texte
|
|
|
UNION
|
|
|
SELECT
|
|
|
'CTI_BUD_MT_EMI_FAVA' AS code, 'Budget. CA EMI Facturé + Valorisé' AS texte,'Montant EMI F+V' AS entete, 'Montant EMI facturé + valorisé' AS entete_etendue, '#E' AS output_format,
|
|
|
'FACTURATION_CLINIQUE' AS table_name,
|
|
|
'CASE WHEN prestation_code IN (''EMI'') THEN montant_facture+montant_encours ELSE 0 END' AS column_name,
|
|
|
'SUM' AS total_function,
|
|
|
'1' AS dimension_date_1,
|
|
|
'2' AS dimension_date_2,
|
|
|
'3' AS dimension_date_3,
|
|
|
'4' AS dimension_date_4,
|
|
|
'' AS dimension_date_5,
|
|
|
'1' AS is_cti,
|
|
|
nextval('w_indicateur_budget_sequence'::regclass) AS numero,
|
|
|
'MTEMI'::text AS indicateur_budget_code,
|
|
|
'CA EMI'::text AS indicateur_budget_texte,
|
|
|
'CTI_BUD_MT_EMI_FAVA#1' AS indicateur_code,
|
|
|
'04'::text AS rapport_chapitre_code,
|
|
|
'Externes et divers'::text AS rapport_chapitre_texte
|
|
|
;
|
|
|
|
|
|
INSERT INTO activite.t_indicateurs (
|
|
|
code, texte, entete, entete_etendue, output_format,
|
|
|
table_name, column_name, total_function,
|
|
|
dimension_date_1, dimension_date_2, dimension_date_3, dimension_date_4, dimension_date_5,
|
|
|
is_cti, is_hide
|
|
|
)
|
|
|
SELECT code, texte, entete, entete_etendue, output_format,
|
|
|
table_name, column_name, total_function,
|
|
|
dimension_date_1, dimension_date_2, dimension_date_3, dimension_date_4, dimension_date_5,
|
|
|
is_cti, '0' AS is_hide
|
|
|
FROM w_indicateurs_budget
|
|
|
JOIN w_budget_settings t_budget ON t_budget.cle_budgetaire_activite IN ('CTIMEDSEJ')
|
|
|
WHERE code NOT IN (SELECT code FROM activite.t_indicateurs WHERE code IS NOT NULL)
|
|
|
;
|
|
|
|
|
|
UPDATE activite.t_indicateurs SET
|
|
|
texte = w_indicateurs_budget.texte,
|
|
|
entete = w_indicateurs_budget.entete,
|
|
|
entete_etendue = w_indicateurs_budget.entete_etendue,
|
|
|
table_name = w_indicateurs_budget.table_name,
|
|
|
column_name = w_indicateurs_budget.column_name,
|
|
|
dimension_date_1 = w_indicateurs_budget.dimension_date_1,
|
|
|
dimension_date_2 = w_indicateurs_budget.dimension_date_2,
|
|
|
dimension_date_3 = w_indicateurs_budget.dimension_date_3,
|
|
|
dimension_date_4 = w_indicateurs_budget.dimension_date_4,
|
|
|
dimension_date_5 = w_indicateurs_budget.dimension_date_5
|
|
|
FROM w_indicateurs_budget
|
|
|
WHERE t_indicateurs.code = w_indicateurs_budget.code AND
|
|
|
(
|
|
|
t_indicateurs.texte IS DISTINCT FROM w_indicateurs_budget.texte OR
|
|
|
t_indicateurs.entete IS DISTINCT FROM w_indicateurs_budget.entete OR
|
|
|
t_indicateurs.entete_etendue IS DISTINCT FROM w_indicateurs_budget.entete_etendue OR
|
|
|
t_indicateurs.table_name IS DISTINCT FROM w_indicateurs_budget.table_name OR
|
|
|
t_indicateurs.column_name IS DISTINCT FROM w_indicateurs_budget.column_name OR
|
|
|
t_indicateurs.dimension_date_1 IS DISTINCT FROM w_indicateurs_budget.dimension_date_1 OR
|
|
|
t_indicateurs.dimension_date_2 IS DISTINCT FROM w_indicateurs_budget.dimension_date_2 OR
|
|
|
t_indicateurs.dimension_date_3 IS DISTINCT FROM w_indicateurs_budget.dimension_date_3 OR
|
|
|
t_indicateurs.dimension_date_4 IS DISTINCT FROM w_indicateurs_budget.dimension_date_4 OR
|
|
|
t_indicateurs.dimension_date_5 IS DISTINCT FROM w_indicateurs_budget.dimension_date_5
|
|
|
)
|
|
|
;
|
|
|
|
|
|
|
|
|
PERFORM base.cti_reorganize_indicateurs('activite')
|
|
|
;
|
|
|
|
|
|
-- Indicateurs calculés
|
|
|
UPDATE activite.t_indicateurs
|
|
|
SET indicateur_associe_1_id = t_indicateurs_associe.oid
|
|
|
FROM activite.t_indicateurs t_indicateurs_associe
|
|
|
WHERE t_indicateurs.code = 'CTI_BUD_GHSM_HOAM_MCO' AND
|
|
|
t_indicateurs_associe.code = 'CTI_BUD_MT_RUBMED_HOAM_MCO_FAVA#1'
|
|
|
;
|
|
|
|
|
|
UPDATE activite.t_indicateurs
|
|
|
SET indicateur_associe_2_id = t_indicateurs_associe.oid
|
|
|
FROM activite.t_indicateurs t_indicateurs_associe
|
|
|
WHERE t_indicateurs.code = 'CTI_BUD_GHSM_HOAM_MCO' AND
|
|
|
t_indicateurs_associe.code = 'CTI_BUD_EMC_HOAM_MCO'
|
|
|
;
|
|
|
|
|
|
UPDATE base.t_budget_indicateur SET
|
|
|
code = to_char(w_indicateurs_budget.numero,'FM00') || w_indicateurs_budget.indicateur_budget_code,
|
|
|
texte = w_indicateurs_budget.indicateur_budget_texte,
|
|
|
indicateur_id = t_indicateurs.oid
|
|
|
FROM w_budget_settings t_budget, w_indicateurs_budget
|
|
|
JOIN activite.t_indicateurs ON w_indicateurs_budget.indicateur_code = t_indicateurs.code
|
|
|
WHERE t_budget_indicateur.budget_id = current_budget_id AND
|
|
|
t_budget.cle_budgetaire_activite IN ('CTIMEDSEJ') AND
|
|
|
substr(t_budget_indicateur.code,3) = w_indicateurs_budget.indicateur_budget_code AND
|
|
|
(
|
|
|
t_budget_indicateur.code <> (to_char(w_indicateurs_budget.numero,'FM00') || w_indicateurs_budget.indicateur_budget_code) OR
|
|
|
t_budget_indicateur.texte <> w_indicateurs_budget.indicateur_budget_texte OR
|
|
|
t_budget_indicateur.indicateur_id <> t_indicateurs.oid
|
|
|
)
|
|
|
;
|
|
|
|
|
|
INSERT INTO base.t_budget_indicateur (code, texte, budget_id, indicateur_id, indicateur_module, actif)
|
|
|
SELECT to_char(w_indicateurs_budget.numero,'FM00') || w_indicateurs_budget.indicateur_budget_code,
|
|
|
w_indicateurs_budget.indicateur_budget_texte,
|
|
|
t_budget.current_budget_id AS budget_id,
|
|
|
t_indicateurs.oid AS indicateur_id,
|
|
|
'activite' AS indicateur_module,
|
|
|
'1' AS actif
|
|
|
FROM w_indicateurs_budget
|
|
|
JOIN activite.t_indicateurs ON w_indicateurs_budget.indicateur_code = t_indicateurs.code
|
|
|
JOIN w_budget_settings t_budget ON t_budget.cle_budgetaire_activite = 'CTIMEDSEJ'
|
|
|
LEFT JOIN base.t_budget_indicateur ON
|
|
|
t_budget_indicateur.budget_id = t_budget.current_budget_id AND
|
|
|
t_budget_indicateur.code = to_char(w_indicateurs_budget.numero,'FM00') || w_indicateurs_budget.indicateur_budget_code
|
|
|
WHERE t_budget_indicateur.oid IS NULL
|
|
|
;
|
|
|
END IF;
|
|
|
|
|
|
|
|
|
-- Rapports Global
|
|
|
IF EXISTS (SELECT * FROM w_budget_settings WHERE cle_budgetaire_activite IN ('CTIMEDSEJ')) THEN
|
|
|
|
|
|
INSERT INTO activite.t_rapports(code, texte, is_cti, is_essentiel, group_id)
|
|
|
SELECT 'CTI_BUDG_1', 'Suivi Budget (total)', '1', '1', 4
|
|
|
WHERE 'CTI_BUDG_1' NOT IN (SELECT code FROM activite.t_rapports WHERE code IS NOT NULL)
|
|
|
;
|
|
|
|
|
|
DELETE FROM activite.t_rapports_rubriques
|
|
|
WHERE rapport_id IN (SELECT oid FROM activite.t_rapports WHERE code = 'CTI_BUDG_1')
|
|
|
;
|
|
|
|
|
|
DROP SEQUENCE IF EXISTS w_rapport_rubrique_sequence;
|
|
|
CREATE TEMP SEQUENCE w_rapport_rubrique_sequence;
|
|
|
|
|
|
INSERT INTO activite.t_rapports_rubriques(
|
|
|
rapport_id, numero_rubrique, indicateur_id, entete_etendue,
|
|
|
row_height, padding, font_size, font_weight, border_thickness, color, background_color,
|
|
|
viewlink, viewlink_label, viewlink_param
|
|
|
)
|
|
|
SELECT
|
|
|
t_rapports.oid AS rapport_id,
|
|
|
nextval('w_indicateur_budget_sequence'::regclass) AS numero_rubrique,
|
|
|
indicateur_id, entete_etendue,
|
|
|
row_height, padding, font_size, font_weight, border_thickness, color, background_color,
|
|
|
viewlink, viewlink_label, viewlink_param
|
|
|
FROM activite.t_rapports
|
|
|
JOIN
|
|
|
(
|
|
|
SELECT
|
|
|
rapport_chapitre_code,
|
|
|
0::bigint AS indicateurs_budget_numero,
|
|
|
MAX(rapport_chapitre_texte) AS entete_etendue,
|
|
|
MAX(t_indicateurs.oid) AS indicateur_id,
|
|
|
26::integer AS row_height,
|
|
|
0::integer AS padding,
|
|
|
14::integer AS font_size,
|
|
|
'bold'::text AS font_weight,
|
|
|
2::integer AS border_thickness,
|
|
|
'0xc0392b'::text AS color,
|
|
|
'0xcccccc'::text AS background_color,
|
|
|
''::text AS viewlink,
|
|
|
''::text AS viewlink_label,
|
|
|
''::text AS viewlink_param
|
|
|
FROM w_indicateurs_budget
|
|
|
JOIN activite.t_indicateurs ON t_indicateurs.code = 'CTI_SEP'
|
|
|
JOIN w_budget_settings ON 1=1
|
|
|
JOIN base.t_budget_indicateur ON
|
|
|
t_budget_indicateur.code = (to_char(w_indicateurs_budget.numero,'FM00') || w_indicateurs_budget.indicateur_budget_code) AND
|
|
|
t_budget_indicateur.budget_id = current_budget_id
|
|
|
WHERE t_budget_indicateur.actif IS DISTINCT FROM '0'
|
|
|
GROUP BY 1
|
|
|
UNION
|
|
|
SELECT
|
|
|
rapport_chapitre_code,
|
|
|
w_indicateurs_budget.numero,
|
|
|
indicateur_budget_texte AS entete_etendue,
|
|
|
t_indicateurs.oid AS indicateur_id,
|
|
|
22::integer AS row_height,
|
|
|
10::integer AS padding,
|
|
|
12::integer AS font_size,
|
|
|
''::text AS font_weight,
|
|
|
0::integer AS border_thickness,
|
|
|
''::text AS color,
|
|
|
''::text AS background_color,
|
|
|
''::text AS viewlink,
|
|
|
''::text AS viewlink_label,
|
|
|
''::text AS viewlink_param
|
|
|
FROM w_indicateurs_budget
|
|
|
JOIN activite.t_indicateurs ON w_indicateurs_budget.indicateur_code = t_indicateurs.code
|
|
|
JOIN w_budget_settings ON 1=1
|
|
|
JOIN base.t_budget_indicateur ON
|
|
|
t_budget_indicateur.code = (to_char(w_indicateurs_budget.numero,'FM00') || w_indicateurs_budget.indicateur_budget_code) AND
|
|
|
t_budget_indicateur.budget_id = current_budget_id
|
|
|
WHERE t_budget_indicateur.actif IS DISTINCT FROM '0'
|
|
|
ORDER BY 1,2
|
|
|
) subview ON 1=1
|
|
|
WHERE code = 'CTI_BUDG_1'
|
|
|
;
|
|
|
|
|
|
-- Détail par spécialité et médecin
|
|
|
|
|
|
-- initialisation entete
|
|
|
DROP TABLE IF EXISTS w_rapports_detail;
|
|
|
CREATE TEMP TABLE w_rapports_detail AS
|
|
|
SELECT 'CTI_BUDG_2MCOD1'::text AS code,
|
|
|
'Suivi Budget (détail MCO par spécialité)'::text AS texte,
|
|
|
'Suivi Budget (détail MCO / spécialité)'::text AS label,
|
|
|
'1'::text AS is_cti,
|
|
|
'1'::text AS is_essentiel,
|
|
|
4::bigint AS group_id,
|
|
|
'ENTETE_ETENDUE|VAP101|VAP100|TDP100|BUP100|BTP100|VAP201|VAP200|TDP200|BUP200|BTP200|VAP301|VAP300|TDP300|BUP300|BTP300|VAP401|VAP400|TDP400|BUP400|BTP400'::text AS colonnes_essentiel,
|
|
|
'VAP201:backgroundColor=0xdddddd|VAP200:backgroundColor=0xdddddd|TDP200:backgroundColor=0xdddddd|BUP200:backgroundColor=0xdddddd|BTP200:backgroundColor=0xdddddd|VAP401:backgroundColor=0xdddddd|VAP400:backgroundColor=0xdddddd|TDP400:backgroundColor=0xdddddd|BUP400:backgroundColor=0xdddddd|BTP400:backgroundColor=0xdddddd|'::text AS colonnes_essentiel_style,
|
|
|
Array['CA Séjour','EMC','GHS Moyen','Jours'] AS serie_entete,
|
|
|
'CA Séjour'::text AS entete,
|
|
|
'EMC'::text AS entete_2
|
|
|
UNION
|
|
|
SELECT 'CTI_BUDG_2MCOD2'::text AS code,
|
|
|
'Suivi Budget (détail MCO par médecin)'::text AS texte,
|
|
|
'Suivi Budget (détail MCO / médecin)'::text AS label,
|
|
|
'1'::text AS is_cti,
|
|
|
'1'::text AS is_essentiel,
|
|
|
4::bigint AS group_id,
|
|
|
'ENTETE_ETENDUE|VAP101|VAP100|TDP100|BUP100|BTP100|VAP201|VAP200|TDP200|BUP200|BTP200|VAP301|VAP300|TDP300|BUP300|BTP300|VAP401|VAP400|TDP400|BUP400|BTP400'::text AS colonnes_essentiel,
|
|
|
'VAP201:backgroundColor=0xdddddd|VAP200:backgroundColor=0xdddddd|TDP200:backgroundColor=0xdddddd|BUP200:backgroundColor=0xdddddd|BTP200:backgroundColor=0xdddddd|VAP401:backgroundColor=0xdddddd|VAP400:backgroundColor=0xdddddd|TDP400:backgroundColor=0xdddddd|BUP400:backgroundColor=0xdddddd|BTP400:backgroundColor=0xdddddd|'::text AS colonnes_essentiel_style,
|
|
|
Array['CA Séjour','EMC','GHS Moyen','Jours'] AS serie_entete,
|
|
|
'CA Séjour'::text AS entete,
|
|
|
'EMC'::text AS entete_2
|
|
|
;
|
|
|
|
|
|
INSERT INTO activite.t_rapports(
|
|
|
code,
|
|
|
texte,
|
|
|
label,
|
|
|
is_cti,
|
|
|
is_essentiel,
|
|
|
group_id,
|
|
|
colonnes_essentiel,
|
|
|
colonnes_essentiel_style,
|
|
|
serie_entete,
|
|
|
entete,
|
|
|
entete_2)
|
|
|
SELECT code,
|
|
|
texte,
|
|
|
label,
|
|
|
is_cti,
|
|
|
is_essentiel,
|
|
|
group_id,
|
|
|
colonnes_essentiel,
|
|
|
colonnes_essentiel_style,
|
|
|
serie_entete,
|
|
|
entete,
|
|
|
entete_2
|
|
|
FROM w_rapports_detail
|
|
|
WHERE code NOT IN (SELECT code FROM activite.t_rapports WHERE code IS NOT NULL)
|
|
|
;
|
|
|
|
|
|
UPDATE activite.t_rapports SET
|
|
|
texte = w_rapports_detail.texte,
|
|
|
label = w_rapports_detail.label,
|
|
|
is_cti = w_rapports_detail.is_cti,
|
|
|
is_essentiel = w_rapports_detail.is_essentiel,
|
|
|
group_id = w_rapports_detail.group_id,
|
|
|
colonnes_essentiel = w_rapports_detail.colonnes_essentiel,
|
|
|
colonnes_essentiel_style = w_rapports_detail.colonnes_essentiel_style,
|
|
|
serie_entete = w_rapports_detail.serie_entete,
|
|
|
entete = w_rapports_detail.entete,
|
|
|
entete_2 = w_rapports_detail.entete_2
|
|
|
FROM w_rapports_detail
|
|
|
WHERE t_rapports.code = w_rapports_detail.code AND
|
|
|
(
|
|
|
t_rapports.texte IS DISTINCT FROM w_rapports_detail.texte OR
|
|
|
t_rapports.label IS DISTINCT FROM w_rapports_detail.label OR
|
|
|
t_rapports.is_cti IS DISTINCT FROM w_rapports_detail.is_cti OR
|
|
|
t_rapports.is_essentiel IS DISTINCT FROM w_rapports_detail.is_essentiel OR
|
|
|
t_rapports.group_id IS DISTINCT FROM w_rapports_detail.group_id OR
|
|
|
t_rapports.colonnes_essentiel IS DISTINCT FROM w_rapports_detail.colonnes_essentiel OR
|
|
|
t_rapports.colonnes_essentiel_style IS DISTINCT FROM w_rapports_detail.colonnes_essentiel_style OR
|
|
|
t_rapports.serie_entete IS DISTINCT FROM w_rapports_detail.serie_entete OR
|
|
|
t_rapports.entete IS DISTINCT FROM w_rapports_detail.entete OR
|
|
|
t_rapports.entete_2 IS DISTINCT FROM w_rapports_detail.entete_2
|
|
|
)
|
|
|
;
|
|
|
|
|
|
DELETE FROM activite.t_rapports_rubriques
|
|
|
WHERE rapport_id IN (
|
|
|
SELECT t_rapports.oid
|
|
|
FROM activite.t_rapports
|
|
|
JOIN w_rapports_detail ON t_rapports.code = w_rapports_detail.code
|
|
|
)
|
|
|
;
|
|
|
|
|
|
|
|
|
DROP SEQUENCE IF EXISTS w_rapport_rubrique_sequence;
|
|
|
CREATE TEMP SEQUENCE w_rapport_rubrique_sequence;
|
|
|
|
|
|
|
|
|
INSERT INTO activite.t_rapports_rubriques(
|
|
|
rapport_id, numero_rubrique,
|
|
|
indicateur_id, indicateur_associe_id, serie_indicateur_id,
|
|
|
picto_enabled,
|
|
|
picto_enabled_2,
|
|
|
positif_is_good,
|
|
|
positif_is_good_2,
|
|
|
serie_picto_enabled,
|
|
|
serie_positif_is_good,
|
|
|
indicateur_condition_id,
|
|
|
entete_etendue,
|
|
|
serie_entete_etendue,
|
|
|
row_height, padding, font_size, font_weight, border_thickness, color, background_color,
|
|
|
hide_on_zero_field,
|
|
|
viewlink, viewlink_label, viewlink_param
|
|
|
)
|
|
|
SELECT
|
|
|
rapport_id, nextval('w_indicateur_budget_sequence'::regclass) AS numero_rubrique,
|
|
|
indicateur_id, indicateur_associe_id, serie_indicateur_id,
|
|
|
'1'::text AS picto_enabled,
|
|
|
'1'::text AS picto_enabled_2,
|
|
|
'1'::text AS positif_is_good,
|
|
|
'1'::text AS positif_is_good_2,
|
|
|
Array['1','1','1','1'] AS serie_picto_enabled,
|
|
|
Array['1','1','1','1'] AS serie_positif_is_good,
|
|
|
indicateur_condition_id,
|
|
|
entete_etendue,
|
|
|
array[entete_etendue] AS serie_entete_etendue,
|
|
|
row_height, padding, font_size, font_weight, border_thickness, color, background_color,
|
|
|
CASE WHEN level <> '1' THEN '*SELF' ELSE '' END AS hide_on_zero_field,
|
|
|
viewlink, viewlink_label, viewlink_param
|
|
|
FROM
|
|
|
(
|
|
|
SELECT
|
|
|
t_rapports.oid AS rapport_id,
|
|
|
MAX(t_indicateurs_1.oid) AS indicateur_id,
|
|
|
MAX(t_indicateurs_2.oid) AS indicateur_associe_id,
|
|
|
Array[MAX(t_indicateurs_1.oid),MAX(t_indicateurs_2.oid),MAX(t_indicateurs_3.oid),MAX(t_indicateurs_4.oid)] AS serie_indicateur_id,
|
|
|
CASE WHEN level <> '1' THEN Array[t_indicateur_condition.oid] ELSE NULL END AS indicateur_condition_id,
|
|
|
MAX(rubrique_texte) AS entete_etendue,
|
|
|
MAX(CASE WHEN level = '1' THEN 20 ELSE 18 END) AS row_height,
|
|
|
MAX(CASE WHEN level = '1' THEN 0 ELSE 10 END) AS padding,
|
|
|
MAX(CASE WHEN level = '1' THEN 12 ELSE 10 END) AS font_size,
|
|
|
MAX(CASE WHEN level = '1' THEN 'bold' ELSE '' END) AS font_weight,
|
|
|
MAX(CASE WHEN level = '1' THEN 2 ELSE 0 END) AS border_thickness,
|
|
|
MAX(CASE WHEN level = '1' THEN '0xc0392b' ELSE '' END) AS color,
|
|
|
MAX(CASE WHEN level = '1' THEN '0xcccccc' ELSE '' END) AS background_color,
|
|
|
MAX(''::text) AS viewlink,
|
|
|
MAX(''::text) AS viewlink_label,
|
|
|
MAX(''::text) AS viewlink_param,
|
|
|
section_code,
|
|
|
level,
|
|
|
cle_code
|
|
|
FROM w_indicateurs_budget
|
|
|
JOIN activite.t_rapports ON t_rapports.code = 'CTI_BUDG_2MCOD1'
|
|
|
LEFT JOIN activite.t_indicateurs t_indicateurs_1 ON w_indicateurs_budget.indicateur_code = t_indicateurs_1.code AND t_indicateurs_1.code = 'CTI_BUD_MT_RUBMED_HOAM_MCO_FAVA#1'
|
|
|
LEFT JOIN activite.t_indicateurs t_indicateurs_2 ON w_indicateurs_budget.indicateur_code = t_indicateurs_2.code AND t_indicateurs_2.code = 'CTI_BUD_EMC_HOAM_MCO'
|
|
|
LEFT JOIN activite.t_indicateurs t_indicateurs_3 ON w_indicateurs_budget.indicateur_code = t_indicateurs_3.code AND t_indicateurs_3.code = 'CTI_BUD_GHSM_HOAM_MCO'
|
|
|
LEFT JOIN activite.t_indicateurs t_indicateurs_4 ON w_indicateurs_budget.indicateur_code = t_indicateurs_4.code AND t_indicateurs_4.code = 'CTI_BUD_JOU_HOAM_MCO'
|
|
|
|
|
|
JOIN
|
|
|
(
|
|
|
SELECT
|
|
|
chr(1)::text AS section_code,
|
|
|
'1'::text AS level,
|
|
|
NULL::text AS cle_code,
|
|
|
'TOTAL BUDGET MCO'::text AS rubrique_texte,
|
|
|
NULL::text AS condition_code
|
|
|
UNION
|
|
|
SELECT
|
|
|
t_classes_sections.code AS section_code,
|
|
|
'2'::text AS level,
|
|
|
NULL::text AS cle_code,
|
|
|
t_classes_sections.code || ' ' || t_classes_sections.texte AS rubrique_texte,
|
|
|
'CTI_BUDGETCLE#LS'||to_char(t_classes.sequence,'FM00')||t_classes_sections.oid AS condition_code
|
|
|
FROM activite.t_classes_sections
|
|
|
JOIN activite.t_classes ON classe_id = t_classes.oid AND t_classes.code = 'CTI_SPE_BUDG'
|
|
|
WHERE t_classes_sections.code <> '****'
|
|
|
|
|
|
UNION
|
|
|
SELECT
|
|
|
chr(255) AS section_code,
|
|
|
'2'::text AS level,
|
|
|
NULL::text AS cle_code,
|
|
|
'SANS SPECIALITE' AS rubrique_texte,
|
|
|
'CTI_BUDGETCLE#LS'||to_char(t_classes.sequence,'FM00')||t_classes_sections.oid AS condition_code
|
|
|
FROM activite.t_classes_sections
|
|
|
JOIN activite.t_classes ON classe_id = t_classes.oid AND t_classes.code = 'CTI_SPE_BUDG'
|
|
|
WHERE t_classes_sections.code = '****'
|
|
|
|
|
|
ORDER BY 1,2,3
|
|
|
) subview ON 1=1
|
|
|
LEFT JOIN activite.t_indicateur_condition ON t_indicateur_condition.code = subview.condition_code
|
|
|
GROUP BY
|
|
|
t_rapports.oid,
|
|
|
t_indicateur_condition.oid,
|
|
|
section_code,
|
|
|
level,
|
|
|
cle_code
|
|
|
ORDER BY section_code,
|
|
|
level,
|
|
|
cle_code
|
|
|
) subview
|
|
|
;
|
|
|
|
|
|
|
|
|
|
|
|
DROP SEQUENCE IF EXISTS w_rapport_rubrique_sequence;
|
|
|
CREATE TEMP SEQUENCE w_rapport_rubrique_sequence;
|
|
|
|
|
|
|
|
|
INSERT INTO activite.t_rapports_rubriques(
|
|
|
rapport_id, numero_rubrique,
|
|
|
indicateur_id, indicateur_associe_id, serie_indicateur_id,
|
|
|
picto_enabled,
|
|
|
picto_enabled_2,
|
|
|
positif_is_good,
|
|
|
positif_is_good_2,
|
|
|
serie_picto_enabled,
|
|
|
serie_positif_is_good,
|
|
|
indicateur_condition_id, entete_etendue,
|
|
|
row_height, padding, font_size, font_weight, border_thickness, color, background_color,
|
|
|
hide_on_zero_field,
|
|
|
viewlink, viewlink_label, viewlink_param
|
|
|
)
|
|
|
SELECT
|
|
|
rapport_id, nextval('w_indicateur_budget_sequence'::regclass) AS numero_rubrique,
|
|
|
indicateur_id, indicateur_associe_id, serie_indicateur_id,
|
|
|
'1'::text AS picto_enabled,
|
|
|
'1'::text AS picto_enabled_2,
|
|
|
'1'::text AS positif_is_good,
|
|
|
'1'::text AS positif_is_good_2,
|
|
|
Array['1','1','1','1'] AS serie_picto_enabled,
|
|
|
Array['1','1','1','1'] AS serie_positif_is_good,
|
|
|
indicateur_condition_id, entete_etendue,
|
|
|
row_height, padding, font_size, font_weight, border_thickness, color, background_color,
|
|
|
'*SELF' AS hide_on_zero_field,
|
|
|
viewlink, viewlink_label, viewlink_param
|
|
|
FROM
|
|
|
(
|
|
|
SELECT
|
|
|
t_rapports.oid AS rapport_id,
|
|
|
MAX(t_indicateurs_1.oid) AS indicateur_id,
|
|
|
MAX(t_indicateurs_2.oid) AS indicateur_associe_id,
|
|
|
Array[MAX(t_indicateurs_1.oid),MAX(t_indicateurs_2.oid),MAX(t_indicateurs_3.oid),MAX(t_indicateurs_4.oid)] AS serie_indicateur_id,
|
|
|
Array[t_indicateur_condition.oid] AS indicateur_condition_id,
|
|
|
MAX(rubrique_texte) AS entete_etendue,
|
|
|
MAX(CASE WHEN level = '1' THEN 20 ELSE 18 END) AS row_height,
|
|
|
MAX(CASE WHEN level = '1' THEN 0 ELSE 10 END) AS padding,
|
|
|
MAX(CASE WHEN level = '1' THEN 12 ELSE 10 END) AS font_size,
|
|
|
MAX(CASE WHEN level = '1' THEN 'bold' ELSE '' END) AS font_weight,
|
|
|
MAX(CASE WHEN level = '1' THEN 2 ELSE 0 END) AS border_thickness,
|
|
|
MAX(CASE WHEN level = '1' THEN '0xc0392b' ELSE '' END) AS color,
|
|
|
MAX(CASE WHEN level = '1' THEN '0xcccccc' ELSE '' END) AS background_color,
|
|
|
MAX(''::text) AS viewlink,
|
|
|
MAX(''::text) AS viewlink_label,
|
|
|
MAX(''::text) AS viewlink_param,
|
|
|
section_code,
|
|
|
level,
|
|
|
cle_code
|
|
|
FROM w_indicateurs_budget
|
|
|
JOIN activite.t_rapports ON t_rapports.code = 'CTI_BUDG_2MCOD2'
|
|
|
LEFT JOIN activite.t_indicateurs t_indicateurs_1 ON w_indicateurs_budget.indicateur_code = t_indicateurs_1.code AND t_indicateurs_1.code = 'CTI_BUD_MT_RUBMED_HOAM_MCO_FAVA#1'
|
|
|
LEFT JOIN activite.t_indicateurs t_indicateurs_2 ON w_indicateurs_budget.indicateur_code = t_indicateurs_2.code AND t_indicateurs_2.code = 'CTI_BUD_EMC_HOAM_MCO'
|
|
|
LEFT JOIN activite.t_indicateurs t_indicateurs_3 ON w_indicateurs_budget.indicateur_code = t_indicateurs_3.code AND t_indicateurs_3.code = 'CTI_BUD_GHSM_HOAM_MCO'
|
|
|
LEFT JOIN activite.t_indicateurs t_indicateurs_4 ON w_indicateurs_budget.indicateur_code = t_indicateurs_4.code AND t_indicateurs_4.code = 'CTI_BUD_JOU_HOAM_MCO'
|
|
|
|
|
|
JOIN
|
|
|
(
|
|
|
SELECT
|
|
|
t_classes_sections.code AS section_code,
|
|
|
'1'::text AS level,
|
|
|
NULL::text AS cle_code,
|
|
|
t_classes_sections.code || ' ' || t_classes_sections.texte AS rubrique_texte,
|
|
|
'CTI_BUDGETCLE#LS'||to_char(t_classes.sequence,'FM00')||t_classes_sections.oid AS condition_code
|
|
|
FROM activite.t_classes_sections
|
|
|
JOIN activite.t_classes ON classe_id = t_classes.oid AND t_classes.code = 'CTI_SPE_BUDG'
|
|
|
WHERE t_classes_sections.code <> '****'
|
|
|
UNION
|
|
|
SELECT
|
|
|
t_classes_sections.code AS section_code,
|
|
|
'2'::text AS level,
|
|
|
t_budget_cle.code AS cle_code,
|
|
|
t_budget_cle.code || ' ' || t_budget_cle.texte AS rubrique_texte,
|
|
|
'CTI_BUDGETCLE#DT'||t_budget_cle.oid AS condition_code
|
|
|
FROM activite.t_classes_sections
|
|
|
JOIN activite.t_classes ON classe_id = t_classes.oid AND t_classes.code = 'CTI_SPE_BUDG'
|
|
|
JOIN activite.t_classes_sections_elements ON t_classes_sections_elements.section_id = t_classes_sections.oid
|
|
|
JOIN activite.t_budget_cle ON to_id = t_budget_cle.oid
|
|
|
WHERE t_classes_sections.code <> '****' AND t_budget_cle.code NOT LIKE '*SP%'
|
|
|
UNION
|
|
|
SELECT
|
|
|
t_classes_sections.code AS section_code,
|
|
|
'3'::text AS level,
|
|
|
t_budget_cle.code AS cle_code,
|
|
|
t_budget_cle.texte AS rubrique_texte,
|
|
|
'CTI_BUDGETCLE#DT'||t_budget_cle.oid AS condition_code
|
|
|
FROM activite.t_classes_sections
|
|
|
JOIN activite.t_classes ON classe_id = t_classes.oid AND t_classes.code = 'CTI_SPE_BUDG'
|
|
|
JOIN activite.t_classes_sections_elements ON t_classes_sections_elements.section_id = t_classes_sections.oid
|
|
|
JOIN activite.t_budget_cle ON to_id = t_budget_cle.oid
|
|
|
WHERE t_classes_sections.code <> '****' AND t_budget_cle.code LIKE '*SP%'
|
|
|
UNION
|
|
|
SELECT
|
|
|
chr(255) AS section_code,
|
|
|
'1'::text AS level,
|
|
|
NULL::text AS cle_code,
|
|
|
'SANS SPECIALITE' AS rubrique_texte,
|
|
|
'CTI_BUDGETCLE#LS'||to_char(t_classes.sequence,'FM00')||t_classes_sections.oid AS condition_code
|
|
|
FROM activite.t_classes_sections
|
|
|
JOIN activite.t_classes ON classe_id = t_classes.oid AND t_classes.code = 'CTI_SPE_BUDG'
|
|
|
WHERE t_classes_sections.code = '****'
|
|
|
UNION
|
|
|
SELECT
|
|
|
chr(255) AS section_code,
|
|
|
'2'::text AS level,
|
|
|
t_budget_cle.code AS cle_code,
|
|
|
t_budget_cle.texte AS rubrique_texte,
|
|
|
'CTI_BUDGETCLE#DT'||t_budget_cle.oid AS condition_code
|
|
|
FROM activite.t_classes_sections
|
|
|
JOIN activite.t_classes ON classe_id = t_classes.oid AND t_classes.code = 'CTI_SPE_BUDG'
|
|
|
JOIN activite.t_classes_sections_elements ON t_classes_sections_elements.section_id = t_classes_sections.oid
|
|
|
JOIN activite.t_budget_cle ON to_id = t_budget_cle.oid
|
|
|
WHERE t_classes_sections.code = '****'
|
|
|
ORDER BY 1,2,3
|
|
|
) subview ON 1=1
|
|
|
JOIN activite.t_indicateur_condition ON t_indicateur_condition.code = subview.condition_code
|
|
|
GROUP BY
|
|
|
t_rapports.oid,
|
|
|
t_indicateur_condition.oid,
|
|
|
section_code,
|
|
|
level,
|
|
|
cle_code
|
|
|
ORDER BY section_code,
|
|
|
level,
|
|
|
cle_code
|
|
|
) subview
|
|
|
;
|
|
|
|
|
|
-- Avec template
|
|
|
DROP TABLE IF EXISTS w_sections;
|
|
|
CREATE TEMP TABLE w_sections AS
|
|
|
SELECT
|
|
|
t_budget_cle.oid AS cle_id,
|
|
|
t_budget_cle.code AS cle_code,
|
|
|
t_budget_cle.texte AS cle_texte,
|
|
|
'CTI_BUDGETCLE#DT'||t_budget_cle.oid::text AS cle_condition_code,
|
|
|
COALESCE(CASE WHEN subview_spg.section_code NOT LIKE '**%' THEN subview_spg.section_code ELSE '**' END,'**') AS spg_section_code,
|
|
|
COALESCE(CASE WHEN subview_spg.section_code NOT LIKE '**%' THEN subview_spg.section_texte ELSE 'SANS CHAPITRE' END,'SANS CHAPITRE') AS spg_section_texte,
|
|
|
MAX('CTI_BUDGETCLE#LS'||to_char(COALESCE(subview_spg.sequence,0),'FM00')||COALESCE(subview_spg.section_id,0)) AS spg_condition_code,
|
|
|
COALESCE(CASE WHEN subview_spe.section_code NOT LIKE '**%' THEN subview_spe.section_code ELSE '****' END,'****') AS spe_section_code,
|
|
|
COALESCE(CASE WHEN subview_spe.section_code NOT LIKE '**%' THEN subview_spe.section_texte ELSE 'SANS SPECIALITE' END,'SANS SPECIALITE') AS spe_section_texte,
|
|
|
MAX('CTI_BUDGETCLE#LS'||to_char(COALESCE(subview_spe.sequence,0),'FM00')||COALESCE(subview_spe.section_id,0)) AS spe_condition_code,
|
|
|
4::numeric AS level,
|
|
|
t_budget_cle.code AS rubrique_code,
|
|
|
t_budget_cle.texte AS rubrique_texte,
|
|
|
NULL::text[] AS sortkey
|
|
|
FROM activite.t_budget_cle
|
|
|
LEFT JOIN
|
|
|
(
|
|
|
SELECT t_classes_sections_elements.to_id,
|
|
|
MAX(t_classes.sequence) AS sequence,
|
|
|
MAX(t_classes_sections.oid) AS section_id,
|
|
|
MAX(t_classes_sections.code) AS section_code,
|
|
|
MAX(t_classes_sections.texte) AS section_texte
|
|
|
FROM activite.t_classes_sections
|
|
|
JOIN activite.t_classes ON classe_id = t_classes.oid AND t_classes.code = 'CTI_SPG_BUDG'
|
|
|
JOIN activite.t_classes_sections_elements ON t_classes_sections_elements.section_id = t_classes_sections.oid
|
|
|
GROUP BY 1
|
|
|
) subview_spg ON t_budget_cle.oid = subview_spg.to_id
|
|
|
LEFT JOIN
|
|
|
(
|
|
|
SELECT t_classes_sections_elements.to_id,
|
|
|
MAX(t_classes.sequence) AS sequence,
|
|
|
MAX(t_classes_sections.oid) AS section_id,
|
|
|
MAX(t_classes_sections.code) AS section_code,
|
|
|
MAX(t_classes_sections.texte) AS section_texte
|
|
|
FROM activite.t_classes_sections
|
|
|
JOIN activite.t_classes ON classe_id = t_classes.oid AND t_classes.code = 'CTI_SPE_BUDG'
|
|
|
JOIN activite.t_classes_sections_elements ON t_classes_sections_elements.section_id = t_classes_sections.oid
|
|
|
GROUP BY 1
|
|
|
) subview_spe ON t_budget_cle.oid = subview_spe.to_id
|
|
|
GROUP BY 1,2,3,4,5,6,8,9,11,12,13,14
|
|
|
;
|
|
|
INSERT INTO w_sections
|
|
|
SELECT
|
|
|
0 AS cle_id,
|
|
|
'' AS cle_code,
|
|
|
'' AS cle_texte,
|
|
|
''::text AS cle_condition_code,
|
|
|
spg_section_code,
|
|
|
spg_section_texte,
|
|
|
MAX(spg_condition_code),
|
|
|
spe_section_code,
|
|
|
spe_section_texte,
|
|
|
MAX(spe_condition_code),
|
|
|
3::numeric AS level,
|
|
|
spe_section_code,
|
|
|
spe_section_texte,
|
|
|
NULL::text[] AS sortkey
|
|
|
FROM w_sections
|
|
|
WHERE level = 4
|
|
|
GROUP BY 1,2,3,4,5,6,8,9,11,12,13,14
|
|
|
;
|
|
|
INSERT INTO w_sections
|
|
|
SELECT
|
|
|
0 AS cle_id,
|
|
|
'' AS cle_code,
|
|
|
'' AS cle_texte,
|
|
|
''::text AS cle_condition_code,
|
|
|
spg_section_code,
|
|
|
spg_section_texte,
|
|
|
spg_condition_code,
|
|
|
'' AS spe_section_code,
|
|
|
'' AS spe_section_texte,
|
|
|
'' AS spe_condition_code,
|
|
|
2::numeric AS level,
|
|
|
spg_section_code,
|
|
|
spg_section_texte,
|
|
|
NULL::text[] AS sortkey
|
|
|
FROM w_sections
|
|
|
WHERE level = 4
|
|
|
GROUP BY 1,2,3,4,5,6,7,8,9,10,11,12,13
|
|
|
;
|
|
|
INSERT INTO w_sections
|
|
|
SELECT
|
|
|
0 AS cle_id,
|
|
|
'' AS cle_code,
|
|
|
'' AS cle_texte,
|
|
|
''::text AS cle_condition_code,
|
|
|
0 AS spg_section_code,
|
|
|
'' AS spg_section_texte,
|
|
|
'' AS spg_condition_code,
|
|
|
'' AS spe_section_code,
|
|
|
'' AS spe_section_texte,
|
|
|
'' AS spe_condition_code,
|
|
|
1::numeric AS level,
|
|
|
'****',
|
|
|
'TOTAL MCO',
|
|
|
NULL::text[] AS sortkey
|
|
|
FROM w_sections
|
|
|
WHERE level = 4
|
|
|
GROUP BY 1,2,3,4,5,6,8,9,11,12,13,14
|
|
|
;
|
|
|
|
|
|
UPDATE w_sections
|
|
|
SET sortkey[1] = CASE WHEN level = 1 THEN '' WHEN spg_section_code <> '**' THEN spg_section_code ELSE chr(255) END
|
|
|
;
|
|
|
UPDATE w_sections
|
|
|
SET sortkey[2] = CASE WHEN level <= 2 THEN '' WHEN spe_section_code <> '****' THEN spe_section_code ELSE chr(255) END
|
|
|
;
|
|
|
UPDATE w_sections
|
|
|
SET sortkey[3] = CASE WHEN level <= 3 THEN '' ELSE cle_texte END
|
|
|
;
|
|
|
|
|
|
-- Présentation rapports selon template
|
|
|
UPDATE activite.t_rapports SET
|
|
|
label = t_rapports_template.label,
|
|
|
group_id = t_rapports_template.group_id,
|
|
|
colonnes_essentiel = t_rapports_template.colonnes_essentiel,
|
|
|
entete = t_rapports_template.entete,
|
|
|
entete_2 = t_rapports_template.entete_2,
|
|
|
serie_entete = t_rapports_template.serie_entete,
|
|
|
colonnes_essentiel_style = t_rapports_template.colonnes_essentiel_style
|
|
|
FROM activite.t_rapports t_rapports_template
|
|
|
WHERE (t_rapports.code || '_TEMPLATE') = t_rapports_template.code AND
|
|
|
(
|
|
|
t_rapports.label IS DISTINCT FROM t_rapports_template.label OR
|
|
|
t_rapports.group_id IS DISTINCT FROM t_rapports_template.group_id OR
|
|
|
t_rapports.colonnes_essentiel IS DISTINCT FROM t_rapports_template.colonnes_essentiel OR
|
|
|
t_rapports.entete IS DISTINCT FROM t_rapports_template.entete OR
|
|
|
t_rapports.entete_2 IS DISTINCT FROM t_rapports_template.entete_2 OR
|
|
|
t_rapports.serie_entete IS DISTINCT FROM t_rapports_template.serie_entete OR
|
|
|
t_rapports.colonnes_essentiel_style IS DISTINCT FROM t_rapports_template.colonnes_essentiel_style
|
|
|
)
|
|
|
;
|
|
|
|
|
|
DELETE FROM activite.t_rapports_rubriques
|
|
|
USING
|
|
|
(
|
|
|
SELECT t_rapports.oid
|
|
|
FROM activite.t_rapports
|
|
|
JOIN activite.t_rapports t_rapports_template ON t_rapports_template.code = t_rapports.code || '_TEMPLATE'
|
|
|
WHERE t_rapports.code LIKE '%BUD%'
|
|
|
) subview
|
|
|
WHERE rapport_id = subview.oid
|
|
|
;
|
|
|
|
|
|
|
|
|
-- Rubriques par spécialité selon rubriques
|
|
|
INSERT INTO activite.t_rapports_rubriques(
|
|
|
rapport_id,
|
|
|
numero_rubrique,
|
|
|
indicateur_id,
|
|
|
indicateur_associe_id,
|
|
|
serie_indicateur_id,
|
|
|
indicateur_condition_id,
|
|
|
entete_etendue,
|
|
|
serie_entete_etendue,
|
|
|
row_height,
|
|
|
padding,
|
|
|
font_size,
|
|
|
font_weight,
|
|
|
border_thickness,
|
|
|
color,
|
|
|
background_color,
|
|
|
serie_description,
|
|
|
serie_output_format,
|
|
|
serie_picto_enabled,
|
|
|
serie_positif_is_good,
|
|
|
hide_on_zero_field,
|
|
|
viewlink,
|
|
|
viewlink_label,
|
|
|
viewlink_param
|
|
|
)
|
|
|
SELECT
|
|
|
rapport_id,
|
|
|
row_number() OVER (PARTITION BY rapport_id ORDER BY sortkey, numero_rubrique) AS numero_rubrique,
|
|
|
indicateur_id,
|
|
|
indicateur_associe_id,
|
|
|
serie_indicateur_id,
|
|
|
indicateur_condition_id,
|
|
|
entete_etendue,
|
|
|
Array[entete_etendue] AS serie_entete_etendue,
|
|
|
row_height,
|
|
|
padding,
|
|
|
font_size,
|
|
|
font_weight,
|
|
|
border_thickness,
|
|
|
color,
|
|
|
background_color,
|
|
|
serie_description,
|
|
|
serie_output_format,
|
|
|
serie_picto_enabled,
|
|
|
serie_positif_is_good,
|
|
|
hide_on_zero_field,
|
|
|
viewlink,
|
|
|
viewlink_label,
|
|
|
viewlink_param
|
|
|
FROM
|
|
|
(
|
|
|
SELECT
|
|
|
t_rapports.oid AS rapport_id,
|
|
|
MAX(t_rapports_rubriques_template.numero_rubrique) AS numero_rubrique,
|
|
|
MAX(t_rapports_rubriques_template.indicateur_id) AS indicateur_id,
|
|
|
MAX(t_rapports_rubriques_template.indicateur_associe_id) AS indicateur_associe_id,
|
|
|
MAX(t_rapports_rubriques_template.serie_indicateur_id) AS serie_indicateur_id,
|
|
|
CASE WHEN level <> '1' THEN Array[t_indicateur_condition.oid] ELSE NULL END AS indicateur_condition_id,
|
|
|
MAX(CASE
|
|
|
WHEN t_rapports_rubriques_template.entete_etendue LIKE '%[LIB=SPG]%' THEN spg_section_texte
|
|
|
WHEN t_rapports_rubriques_template.entete_etendue LIKE '%[LIB=SPE]%' THEN spe_section_texte
|
|
|
WHEN t_rapports_rubriques_template.entete_etendue LIKE '%[LIB=CLE]%' THEN cle_texte
|
|
|
ELSE t_rapports_rubriques_template.entete_etendue END) AS entete_etendue,
|
|
|
MAX(t_rapports_rubriques_template.row_height) AS row_height,
|
|
|
MAX(t_rapports_rubriques_template.padding) AS padding,
|
|
|
MAX(t_rapports_rubriques_template.font_size) AS font_size,
|
|
|
MAX(t_rapports_rubriques_template.font_weight) AS font_weight,
|
|
|
MAX(t_rapports_rubriques_template.border_thickness) AS border_thickness,
|
|
|
MAX(t_rapports_rubriques_template.color) AS color,
|
|
|
MAX(t_rapports_rubriques_template.background_color) AS background_color,
|
|
|
MAX(t_rapports_rubriques_template.serie_description) AS serie_description,
|
|
|
MAX(t_rapports_rubriques_template.serie_output_format) AS serie_output_format,
|
|
|
MAX(t_rapports_rubriques_template.serie_picto_enabled) AS serie_picto_enabled,
|
|
|
MAX(t_rapports_rubriques_template.serie_positif_is_good) AS serie_positif_is_good,
|
|
|
MAX(t_rapports_rubriques_template.hide_on_zero_field) AS hide_on_zero_field,
|
|
|
MAX(''::text) AS viewlink,
|
|
|
MAX(''::text) AS viewlink_label,
|
|
|
MAX(''::text) AS viewlink_param,
|
|
|
MAX(t_indicateurs.code) AS indicateur_code,
|
|
|
sortkey,
|
|
|
level
|
|
|
FROM activite.t_rapports t_rapports_template
|
|
|
JOIN activite.t_rapports_rubriques t_rapports_rubriques_template ON t_rapports_rubriques_template.rapport_id = t_rapports_template.oid
|
|
|
JOIN activite.t_indicateurs ON t_rapports_rubriques_template.indicateur_id = t_indicateurs.oid
|
|
|
JOIN activite.t_rapports ON t_rapports_template.code = t_rapports.code || '_TEMPLATE' AND t_rapports.code LIKE '%BUD%'
|
|
|
JOIN w_sections ON 1=1
|
|
|
LEFT JOIN activite.t_indicateur_condition ON
|
|
|
t_indicateur_condition.code = w_sections.spg_condition_code AND level = 2 OR
|
|
|
t_indicateur_condition.code = w_sections.spe_condition_code AND level = 3 OR
|
|
|
t_indicateur_condition.code = w_sections.cle_condition_code AND level = 4
|
|
|
WHERE
|
|
|
(
|
|
|
level = 1 AND t_rapports_rubriques_template.option LIKE '%[LVL=TOT]%' OR
|
|
|
level = 2 AND t_rapports_rubriques_template.option LIKE '%[LVL=SPG]%' OR
|
|
|
level = 3 AND t_rapports_rubriques_template.option LIKE '%[LVL=SPE]%' OR
|
|
|
level = 4 AND t_rapports_rubriques_template.option LIKE '%[LVL=CLE]%'
|
|
|
)
|
|
|
GROUP BY
|
|
|
t_rapports.oid,
|
|
|
t_rapports_rubriques_template.rapport_id,
|
|
|
t_rapports_rubriques_template.numero_rubrique,
|
|
|
t_indicateur_condition.oid,
|
|
|
sortkey,
|
|
|
level
|
|
|
ORDER BY
|
|
|
t_rapports_rubriques_template.rapport_id,
|
|
|
sortkey,
|
|
|
level,
|
|
|
t_rapports_rubriques_template.numero_rubrique
|
|
|
) subview
|
|
|
;
|
|
|
|
|
|
|
|
|
|
|
|
END IF;
|
|
|
|
|
|
-- Rapports
|
|
|
IF EXISTS (SELECT * FROM w_budget_settings WHERE cle_budgetaire_activite IN ('CTIFILMEDSEJ')) THEN
|
|
|
|
|
|
DROP TABLE IF EXISTS w_sections_2;
|
|
|
CREATE TEMP TABLE w_sections_2 AS
|
|
|
SELECT
|
|
|
t_budget_cle.oid AS cle_id,
|
|
|
t_budget_cle.code AS cle_code,
|
|
|
t_budget_cle.texte AS cle_texte,
|
|
|
'CTI_BUDGETCLE#DT'||t_budget_cle.oid::text AS cle_condition_code,
|
|
|
COALESCE(CASE WHEN subview_fil.section_code NOT LIKE '**%' THEN subview_fil.section_code ELSE '**' END,'**') AS fil_section_code,
|
|
|
COALESCE(CASE WHEN subview_fil.section_code NOT LIKE '**%' THEN subview_fil.section_texte ELSE 'SANS FILIERE' END,'SANS FILIERE') AS fil_section_texte,
|
|
|
MAX('CTI_BUDGETCLE#LS'||to_char(COALESCE(subview_fil.sequence,0),'FM00')||COALESCE(subview_fil.section_id,0)) AS fil_condition_code,
|
|
|
COALESCE(CASE WHEN subview_med.section_code NOT LIKE '**%' THEN subview_med.section_code ELSE '****' END,'****') AS med_section_code,
|
|
|
COALESCE(CASE WHEN subview_med.section_code NOT LIKE '**%' THEN subview_med.section_texte ELSE 'SANS MEDECIN' END,'MEDECIN') AS med_section_texte,
|
|
|
MAX('CTI_BUDGETCLE#LS'||to_char(COALESCE(subview_med.sequence,0),'FM00')||COALESCE(subview_med.section_id,0)) AS med_condition_code,
|
|
|
4::numeric AS level,
|
|
|
t_budget_cle.code AS rubrique_code,
|
|
|
t_budget_cle.texte AS rubrique_texte,
|
|
|
NULL::text[] AS sortkey
|
|
|
FROM activite.t_budget_cle
|
|
|
LEFT JOIN
|
|
|
(
|
|
|
SELECT t_classes_sections_elements.to_id,
|
|
|
MAX(t_classes.sequence) AS sequence,
|
|
|
MAX(t_classes_sections.oid) AS section_id,
|
|
|
MAX(t_classes_sections.code) AS section_code,
|
|
|
MAX(t_classes_sections.texte) AS section_texte
|
|
|
FROM activite.t_classes_sections
|
|
|
JOIN activite.t_classes ON classe_id = t_classes.oid AND t_classes.code = 'CTI_FIL_BUDG'
|
|
|
JOIN activite.t_classes_sections_elements ON t_classes_sections_elements.section_id = t_classes_sections.oid
|
|
|
GROUP BY 1
|
|
|
) subview_fil ON t_budget_cle.oid = subview_fil.to_id
|
|
|
LEFT JOIN
|
|
|
(
|
|
|
SELECT t_classes_sections_elements.to_id,
|
|
|
MAX(t_classes.sequence) AS sequence,
|
|
|
MAX(t_classes_sections.oid) AS section_id,
|
|
|
MAX(t_classes_sections.code) AS section_code,
|
|
|
MAX(t_classes_sections.texte) AS section_texte
|
|
|
FROM activite.t_classes_sections
|
|
|
JOIN activite.t_classes ON classe_id = t_classes.oid AND t_classes.code = 'CTI_MED_BUDG'
|
|
|
JOIN activite.t_classes_sections_elements ON t_classes_sections_elements.section_id = t_classes_sections.oid
|
|
|
GROUP BY 1
|
|
|
) subview_med ON t_budget_cle.oid = subview_med.to_id
|
|
|
GROUP BY 1,2,3,4,5,6,8,9,11,12,13,14
|
|
|
;
|
|
|
|
|
|
|
|
|
|
|
|
DROP TABLE IF EXISTS w_sections;
|
|
|
CREATE TEMP TABLE w_sections AS
|
|
|
SELECT
|
|
|
'FILMED'::text AS lvl_code,
|
|
|
fil_section_code AS lv1_section_code,
|
|
|
fil_section_code || ' ' || fil_section_texte AS lv1_section_texte,
|
|
|
MAX(fil_condition_code) AS lv1_condition_code,
|
|
|
med_section_code AS lv2_section_code,
|
|
|
med_section_texte AS lv2_section_texte,
|
|
|
MAX(med_condition_code) AS lv2_condition_code,
|
|
|
3::numeric AS level,
|
|
|
med_section_code AS ent_code,
|
|
|
med_section_texte AS ent_texte,
|
|
|
NULL::text[] AS sortkey
|
|
|
FROM w_sections_2
|
|
|
WHERE level = 4 AND
|
|
|
fil_section_code NOT LIKE '**%' AND
|
|
|
med_section_code NOT LIKE '**%'
|
|
|
GROUP BY 1,2,3,5,6,9,10,11
|
|
|
;
|
|
|
INSERT INTO w_sections
|
|
|
SELECT
|
|
|
'MEDFIL'::text AS lvl_code,
|
|
|
med_section_code AS lv1_section_code,
|
|
|
med_section_texte AS lv1_section_texte,
|
|
|
MAX(med_condition_code) AS lv1_condition_code,
|
|
|
fil_section_code AS lv2_section_code,
|
|
|
fil_section_code || ' ' || fil_section_texte AS lv2_section_texte,
|
|
|
MAX(fil_condition_code) AS lv2_condition_code,
|
|
|
3::numeric AS level,
|
|
|
fil_section_code AS code,
|
|
|
fil_section_code || ' ' || fil_section_texte AS texte,
|
|
|
NULL::text[] AS sortkey
|
|
|
FROM w_sections_2
|
|
|
WHERE level = 4 AND
|
|
|
fil_section_code NOT LIKE '**%' AND
|
|
|
med_section_code NOT LIKE '**%'
|
|
|
GROUP BY 1,2,3,5,6,9,10,11
|
|
|
;
|
|
|
INSERT INTO w_sections
|
|
|
SELECT
|
|
|
'FIL'::text AS lvl_code,
|
|
|
fil_section_code,
|
|
|
fil_section_code || ' ' || fil_section_texte,
|
|
|
MAX(fil_condition_code),
|
|
|
'' AS lv2_section_code,
|
|
|
'' AS lv2_section_texte,
|
|
|
'' AS lv2_condition_code,
|
|
|
2::numeric AS level,
|
|
|
fil_section_code,
|
|
|
fil_section_code || ' ' || fil_section_texte,
|
|
|
NULL::text[] AS sortkey
|
|
|
FROM w_sections_2
|
|
|
WHERE level = 4 AND
|
|
|
fil_section_code NOT LIKE '**%'
|
|
|
GROUP BY 1,2,3,5,6,9,10,11
|
|
|
;
|
|
|
INSERT INTO w_sections
|
|
|
SELECT
|
|
|
'MED'::text AS lvl_code,
|
|
|
med_section_code,
|
|
|
med_section_texte,
|
|
|
MAX(med_condition_code),
|
|
|
'' AS lv2_section_code,
|
|
|
'' AS lv2_section_texte,
|
|
|
'' AS lv2_condition_code,
|
|
|
2::numeric AS level,
|
|
|
med_section_code,
|
|
|
med_section_texte,
|
|
|
NULL::text[] AS sortkey
|
|
|
FROM w_sections_2
|
|
|
WHERE level = 4 AND
|
|
|
med_section_code NOT LIKE '**%'
|
|
|
GROUP BY 1,2,3,5,6,9,10,11
|
|
|
;
|
|
|
INSERT INTO w_sections
|
|
|
SELECT
|
|
|
'TOT'::text AS lvl_code,
|
|
|
'' AS lv1_section_code,
|
|
|
'' AS lv1_section_texte,
|
|
|
'' AS lv1_condition_code,
|
|
|
'' AS lv2_section_code,
|
|
|
'' AS lv2_section_texte,
|
|
|
'' AS lv2_condition_code,
|
|
|
1::numeric AS level,
|
|
|
'****',
|
|
|
'TOTAL',
|
|
|
NULL::text[] AS sortkey
|
|
|
FROM w_sections_2
|
|
|
WHERE level = 4
|
|
|
GROUP BY 1,2,3,5,6,9,10,11
|
|
|
;
|
|
|
|
|
|
UPDATE w_sections
|
|
|
SET sortkey[1] = CASE WHEN level = 1 THEN '' WHEN lv1_section_code <> '**' THEN lv1_section_texte ELSE chr(255) END
|
|
|
;
|
|
|
UPDATE w_sections
|
|
|
SET sortkey[2] = CASE WHEN level <= 2 THEN '' WHEN lv2_section_code <> '****' THEN lv2_section_texte ELSE chr(255) END
|
|
|
;
|
|
|
|
|
|
UPDATE activite.t_rapports SET
|
|
|
label = t_rapports_template.label,
|
|
|
group_id = t_rapports_template.group_id,
|
|
|
colonnes_essentiel = t_rapports_template.colonnes_essentiel,
|
|
|
entete = t_rapports_template.entete,
|
|
|
entete_2 = t_rapports_template.entete_2,
|
|
|
serie_entete = t_rapports_template.serie_entete,
|
|
|
colonnes_essentiel_style = t_rapports_template.colonnes_essentiel_style
|
|
|
FROM activite.t_rapports t_rapports_template
|
|
|
WHERE (t_rapports.code || '_TEMPLATE') = t_rapports_template.code AND
|
|
|
(
|
|
|
t_rapports.label IS DISTINCT FROM t_rapports_template.label OR
|
|
|
t_rapports.group_id IS DISTINCT FROM t_rapports_template.group_id OR
|
|
|
t_rapports.colonnes_essentiel IS DISTINCT FROM t_rapports_template.colonnes_essentiel OR
|
|
|
t_rapports.entete IS DISTINCT FROM t_rapports_template.entete OR
|
|
|
t_rapports.entete_2 IS DISTINCT FROM t_rapports_template.entete_2 OR
|
|
|
t_rapports.serie_entete IS DISTINCT FROM t_rapports_template.serie_entete OR
|
|
|
t_rapports.colonnes_essentiel_style IS DISTINCT FROM t_rapports_template.colonnes_essentiel_style
|
|
|
)
|
|
|
;
|
|
|
|
|
|
|
|
|
DELETE FROM activite.t_rapports_rubriques
|
|
|
USING
|
|
|
(
|
|
|
SELECT t_rapports.oid
|
|
|
FROM activite.t_rapports
|
|
|
JOIN activite.t_rapports t_rapports_template ON t_rapports_template.code = t_rapports.code || '_TEMPLATE'
|
|
|
WHERE t_rapports.code LIKE '%BUD%'
|
|
|
) subview
|
|
|
WHERE rapport_id = subview.oid
|
|
|
;
|
|
|
|
|
|
|
|
|
-- Rubriques par spécialité selon rubriques
|
|
|
INSERT INTO activite.t_rapports_rubriques(
|
|
|
rapport_id,
|
|
|
numero_rubrique,
|
|
|
indicateur_id,
|
|
|
indicateur_associe_id,
|
|
|
serie_indicateur_id,
|
|
|
indicateur_condition_id,
|
|
|
entete_etendue,
|
|
|
serie_entete_etendue,
|
|
|
row_height,
|
|
|
padding,
|
|
|
font_size,
|
|
|
font_weight,
|
|
|
border_thickness,
|
|
|
color,
|
|
|
background_color,
|
|
|
serie_description,
|
|
|
serie_output_format,
|
|
|
serie_picto_enabled,
|
|
|
serie_positif_is_good,
|
|
|
hide_on_zero_field,
|
|
|
viewlink,
|
|
|
viewlink_label,
|
|
|
viewlink_param,
|
|
|
option
|
|
|
)
|
|
|
SELECT
|
|
|
rapport_id,
|
|
|
row_number() OVER (PARTITION BY rapport_id ORDER BY numero_rubrique_chapitre, sortkey, numero_rubrique) AS numero_rubrique,
|
|
|
indicateur_id,
|
|
|
indicateur_associe_id,
|
|
|
serie_indicateur_id,
|
|
|
indicateur_condition_id,
|
|
|
entete_etendue,
|
|
|
Array[entete_etendue] AS serie_entete_etendue,
|
|
|
row_height,
|
|
|
padding,
|
|
|
font_size,
|
|
|
font_weight,
|
|
|
border_thickness,
|
|
|
color,
|
|
|
background_color,
|
|
|
serie_description,
|
|
|
serie_output_format,
|
|
|
serie_picto_enabled,
|
|
|
serie_positif_is_good,
|
|
|
hide_on_zero_field,
|
|
|
viewlink,
|
|
|
viewlink_label,
|
|
|
viewlink_param,
|
|
|
option
|
|
|
FROM
|
|
|
(
|
|
|
SELECT
|
|
|
t_rapports.oid AS rapport_id,
|
|
|
numero_rubrique_chapitre,
|
|
|
MAX(t_rapports_rubriques_template.numero_rubrique) AS numero_rubrique,
|
|
|
MAX(t_rapports_rubriques_template.indicateur_id) AS indicateur_id,
|
|
|
MAX(t_rapports_rubriques_template.indicateur_associe_id) AS indicateur_associe_id,
|
|
|
MAX(t_rapports_rubriques_template.serie_indicateur_id) AS serie_indicateur_id,
|
|
|
CASE WHEN level <> '1' THEN Array[t_indicateur_condition_2.oid,t_indicateur_condition_3.oid] ELSE NULL END AS indicateur_condition_id,
|
|
|
MAX(CASE
|
|
|
WHEN t_rapports_rubriques_template.entete_etendue LIKE '%[LIB=FIL]%' THEN ent_texte
|
|
|
WHEN t_rapports_rubriques_template.entete_etendue LIKE '%[LIB=MED]%' THEN ent_texte
|
|
|
ELSE t_rapports_rubriques_template.entete_etendue END) AS entete_etendue,
|
|
|
MAX(t_rapports_rubriques_template.row_height) AS row_height,
|
|
|
MAX(t_rapports_rubriques_template.padding) AS padding,
|
|
|
MAX(t_rapports_rubriques_template.font_size) AS font_size,
|
|
|
MAX(t_rapports_rubriques_template.font_weight) AS font_weight,
|
|
|
MAX(t_rapports_rubriques_template.border_thickness) AS border_thickness,
|
|
|
MAX(t_rapports_rubriques_template.color) AS color,
|
|
|
MAX(t_rapports_rubriques_template.background_color) AS background_color,
|
|
|
MAX(t_rapports_rubriques_template.serie_description) AS serie_description,
|
|
|
MAX(t_rapports_rubriques_template.serie_output_format) AS serie_output_format,
|
|
|
MAX(t_rapports_rubriques_template.serie_picto_enabled) AS serie_picto_enabled,
|
|
|
MAX(t_rapports_rubriques_template.serie_positif_is_good) AS serie_positif_is_good,
|
|
|
MAX(t_rapports_rubriques_template.hide_on_zero_field) AS hide_on_zero_field,
|
|
|
MAX(''::text) AS viewlink,
|
|
|
MAX(''::text) AS viewlink_label,
|
|
|
MAX(''::text) AS viewlink_param,
|
|
|
MAX(t_indicateurs.code) AS indicateur_code,
|
|
|
MAX(t_rapports_rubriques_template.option) AS option,
|
|
|
sortkey,
|
|
|
level
|
|
|
FROM activite.t_rapports t_rapports_template
|
|
|
JOIN activite.t_rapports_rubriques t_rapports_rubriques_template ON t_rapports_rubriques_template.rapport_id = t_rapports_template.oid
|
|
|
JOIN activite.t_indicateurs ON t_rapports_rubriques_template.indicateur_id = t_indicateurs.oid
|
|
|
JOIN activite.t_rapports ON t_rapports_template.code = t_rapports.code || '_TEMPLATE' AND t_rapports.code LIKE '%BUD%'
|
|
|
JOIN (
|
|
|
SELECT rapport_id,
|
|
|
numero_rubrique AS numero_rubrique_chapitre,
|
|
|
COALESCE(LEAD(numero_rubrique) OVER (PARTITION BY rapport_id oRDER BY numero_rubrique) -1,999999) AS numero_rubrique_chapitre_fin
|
|
|
FROM activite.t_rapports_rubriques
|
|
|
JOIN activite.t_rapports ON rapport_id = t_rapports.oid
|
|
|
WHERE t_rapports.code LIKE '%TEMPLATE' AND
|
|
|
option LIKE '%[TREELVL=1]%'
|
|
|
) subview ON
|
|
|
t_rapports_template.oid = subview.rapport_id AND
|
|
|
t_rapports_rubriques_template.numero_rubrique BETWEEN numero_rubrique_chapitre AND numero_rubrique_chapitre_fin
|
|
|
JOIN w_sections ON 1=1
|
|
|
LEFT JOIN activite.t_indicateur_condition t_indicateur_condition_2 ON
|
|
|
t_indicateur_condition_2.code = w_sections.lv1_condition_code AND level >= 2
|
|
|
LEFT JOIN activite.t_indicateur_condition t_indicateur_condition_3 ON
|
|
|
t_indicateur_condition_3.code = w_sections.lv2_condition_code AND level = 3
|
|
|
WHERE
|
|
|
(
|
|
|
level = 1 AND t_rapports_rubriques_template.option LIKE '%[LVL='||w_sections.lvl_code||']%' OR
|
|
|
level = 2 AND t_rapports_rubriques_template.option LIKE '%[LVL='||w_sections.lvl_code||']%' OR
|
|
|
level = 3 AND t_rapports_rubriques_template.option LIKE '%[LVL='||w_sections.lvl_code||']%'
|
|
|
)
|
|
|
GROUP BY
|
|
|
t_rapports.oid,
|
|
|
t_rapports_rubriques_template.rapport_id,
|
|
|
numero_rubrique_chapitre,
|
|
|
t_rapports_rubriques_template.numero_rubrique,
|
|
|
t_indicateur_condition_2.oid,
|
|
|
t_indicateur_condition_3.oid,
|
|
|
sortkey,
|
|
|
level
|
|
|
ORDER BY
|
|
|
t_rapports_rubriques_template.rapport_id,
|
|
|
numero_rubrique_chapitre,
|
|
|
sortkey,
|
|
|
level,
|
|
|
t_rapports_rubriques_template.numero_rubrique
|
|
|
) subview
|
|
|
;
|
|
|
|
|
|
|
|
|
|
|
|
END IF;
|
|
|
|
|
|
|
|
|
RETURN 'OK' ;
|
|
|
END;
|