return: integer lang: plpgsql parameters: p0: type: bigint name: i_import_id comment: "Pour chaque import, calcule quelques statistiques qu''on pourra retrouver dans les tablaux OVALIDE" src: | DECLARE /* * import_id = 0 --> calculer les stats de tous les imports * import_id = X --> calculer les stats pour l'import X * import_id = -1 --> calculer les stats manquantes */ res integer := 0; request text := ''; cond text :=''; BEGIN -- Vérifie l'existance de la table pmsi.p_imports_stats RAISE NOTICE '%' , 'Check si pmsi.p_imports_stats existe'; IF NOT EXISTS (SELECT table_name FROM information_schema.tables WHERE table_name = 'p_imports_stats' AND table_schema = 'pmsi') THEN RAISE NOTICE '%' , 'Table pmsi.p_imports_stats inexistante'; RETURN 'Table pmsi.p_imports_stats inexistante'; END IF; /* Test de la valeur du paramètre */ IF ($1 = 0) THEN -- truncate de la table des stats avant de recalculer TRUNCATE pmsi.p_imports_stats; cond := ''; ELSIF ($1 > 0) THEN -- delete des stats de l'import à regénérer DELETE FROM pmsi.p_imports_stats where import_id = $1; cond := 'AND p_imports.oid = ' || $1; ELSE cond := 'AND p_imports.oid not in (select import_id FROM pmsi.p_imports_stats)'; END IF; request := ' INSERT INTO pmsi.p_imports_stats ( import_id, nb_rsa_transmis, nb_rsa_traites, nb_rsa_0_nuits, nb_rsa_seances, nb_total_rsa_prestations, br_total_rsa_prestations, nb_sejours_valorises, br_sejours_valorises ) SELECT stats.import_id, max(stats.nb_rsa_transmis) AS nb_rsa_transmis, max(stats.nb_rsa_traites) AS nb_rsa_traites, max(stats.nb_rsa_0_nuits) AS nb_rsa_0_nuits, max(stats.nb_rsa_seances) AS nb_rsa_seances, max(stats.nb_total_rsa_prestations) AS nb_total_rsa_prestations, max(stats.br_total_rsa_prestations) AS br_total_rsa_prestations, max(stats.nb_sejours_valorises) AS nb_sejours_valorises, max(stats.br_sejours_valorises) AS br_sejours_valorises FROM ( ( SELECT p_imports.oid AS import_id, 0 AS nb_rsa_transmis, 0 AS nb_rsa_traites, 0 AS nb_rsa_0_nuits, 0 AS nb_rsa_seances, sum(CASE WHEN v_rss_1.en_cours = ''0'' AND CASE WHEN p_imports.date_fin < ''2013-08-31''::date THEN v_rss_1.traitement_epmsi in (''21'', ''22'', ''23'', ''24'', ''25'', ''26'', ''30'',''31'') AND v_rss_1.nb_factures_nulles = 0 ELSE v_rss_1.nb_factures_nulles = 0 END THEN v_rsf_detail_1.nombre ELSE NULL END) AS nb_total_rsa_prestations, round(sum( CASE WHEN v_rss_1.en_cours = ''0'' AND CASE WHEN p_imports.date_fin < ''2013-08-31''::date THEN v_rss_1.traitement_epmsi in (''21'', ''22'', ''23'', ''24'', ''25'', ''26'', ''30'',''31'') AND v_rss_1.nb_factures_nulles = 0 AND v_rss_1.cmd_code <> ''90'' ELSE v_rss_1.nb_factures_nulles = 0 AND v_rss_1.cmd_code <> ''90'' END THEN COALESCE(v_rsf_detail_1.base_remboursement_sauf_transition,v_rsf_detail_1.base_remboursement) ELSE NULL END)) AS br_total_rsa_prestations, 0 AS nb_sejours_valorises, 0 AS br_sejours_valorises FROM pmsi.v_rss_7 v_rss_1 JOIN pmsi.v_rsf_detail_1 using (rss_id) JOIN pmsi.p_imports ON import_id = p_imports.oid WHERE v_rss_1.cmd_code <> ''15'' AND p_imports.date_debut BETWEEN ''2012-01-01'' AND now() ' || cond || ' group by 1 ) UNION ALL ( SELECT p_imports.oid AS import_id, sum(CASE WHEN v_rss_1.en_cours = ''0'' AND v_rss_1.cas_code != ''*'' THEN 1 ELSE 0 END) AS nb_rsa_transmis, sum(CASE WHEN v_rss_1.en_cours = ''0'' AND v_rss_1.cas_code != ''*'' AND (v_rss_1.traitement_epmsi IN (''15'',''21'',''22'',''23'',''24'',''25'',''30'',''31'',''33'') OR v_rss_1.traitement_epmsi = ''26'' AND v_rss_1.ghm_code NOT LIKE ALL (ARRAY[''14Z08Z'', ''09Z02%'', ''90%'']::text[])) THEN 1 ELSE NULL END) AS nb_rsa_traites, sum(CASE WHEN v_rss_1.en_cours = ''0'' AND v_rss_1.cas_code != ''*'' AND duree_sejour = 0 AND cmd_code NOT IN (''28'', ''90'') AND v_rss_1.traitement_epmsi NOT IN (''11'') THEN 1 ELSE 0 END) AS nb_rsa_0_nuits, sum(CASE WHEN v_rss_1.en_cours = ''0'' AND v_rss_1.cas_code != ''*'' AND v_rss_1.traitement_epmsi IN (''15'',''12'',''99'',''21'',''22'',''23'',''24'',''25'',''26'',''30'',''31'') AND cmd_code = ''28'' THEN 1 ELSE 0 END) AS nb_rsa_seances, 0 AS nb_total_rsa_prestations, 0 AS br_total_rsa_prestations, sum(CASE WHEN v_rss_1.en_cours = ''0'' AND v_rss_1.cas_code != ''*'' AND v_rss_1.traitement_epmsi = ''30'' AND t_finess.type_etablissement = 1 THEN 1 WHEN v_rss_1.en_cours = ''0'' AND v_rss_1.cas_code != ''*'' AND v_rss_1.traitement_epmsi = ''30'' AND t_finess.type_etablissement <> 1 AND t_ghs.code IN (9626, 9628, 9630) THEN 1 WHEN v_rss_1.en_cours = ''0'' AND v_rss_1.cas_code != ''*'' AND v_rss_1.traitement_epmsi = ''30'' AND t_finess.type_etablissement <> 1 THEN nb_rsa ELSE 0 END) AS nb_sejours_valorises, 0 AS br_sejours_valorises FROM pmsi.v_rss_7 v_rss_1 JOIN base.t_finess ON t_finess.code = v_rss_1.finess JOIN pmsi.p_imports ON import_id = p_imports.oid LEFT JOIN pmsi.t_ghs ON t_ghs.oid = v_rss_1.ghs_id WHERE p_imports.date_debut BETWEEN ''2012-01-01'' AND now() ' || cond || ' GROUP BY 1 ) UNION ALL ( SELECT p_imports.oid AS import_id, 0 AS nb_rsa_transmis, 0 AS nb_rsa_traites, 0 AS nb_rsa_0_nuits, 0 AS nb_rsa_seances, 0 AS nb_total_rsa_prestations, 0 AS br_total_rsa_prestations, 0 AS nb_sejours_valorises, round(sum(CASE WHEN v_rss_1.en_cours = ''0'' AND v_rss_1.cas_code != ''*'' AND v_rss_1.traitement_epmsi = ''30'' THEN COALESCE(p_rsf_detail.base_remboursement_sauf_transition,p_rsf_detail.base_remboursement) ELSE 0 END)) AS br_sejours_valorises FROM pmsi.v_rss_7 v_rss_1 JOIN pmsi.p_rsf_detail ON p_rsf_detail.rss_id = v_rss_1.rss_id JOIN base.t_finess ON t_finess.code = v_rss_1.finess JOIN pmsi.p_imports ON import_id = p_imports.oid JOIN pmsi.t_prestations ON prestation_id = t_prestations.oid WHERE p_rsf_detail.est_ligne_rss = ''1'' AND t_prestations.section_code[9] LIKE ''S1%'' AND p_imports.date_debut BETWEEN ''2012-01-01'' AND now() ' || cond || ' GROUP BY 1 ORDER BY 1 ) ) AS stats GROUP BY 1; '; EXECUTE request; GET DIAGNOSTICS res = ROW_COUNT; RETURN res; END;