return: text lang: plpgsql parameters: p0: type: text name: _in_data_profile_code src: | DECLARE _cursor refcursor; _toschema text; _sqlcmd text; _sqlobject text; _data_profile_code text; _tosqlcmd text; _tosqlcmd_deja text; _tosqlcmd_base text; result TEXT; BEGIN -- Suppression si inexistant IF _in_data_profile_code <> '' AND EXISTS (SELECT nspname FROM pg_namespace WHERE LOWER(nspname) = LOWER('rh_data_profile_' || _in_data_profile_code) AND LOWER(substr(nspname,17)) NOT IN (SELECT LOWER(t_data_profile.code) FROM rh.t_data_profile) ) THEN RAISE NOTICE 'Suppression %', 'rh_data_profile_' || _in_data_profile_code; BEGIN EXECUTE 'DROP SCHEMA rh_data_profile_' || _in_data_profile_code || ' CASCADE'; EXCEPTION WHEN others THEN RAISE NOTICE 'Erreur %' , 'DROP SCHEMA ' || 'rh_data_profile_' || _in_data_profile_code || ' CASCADE'; END; return 'OK'; END IF; -- Traitement des listes pour être bien interprétées par string_to_array UPDATE rh.t_data_profile SET etablissement_inclus = trim(etablissement_inclus); UPDATE rh.t_data_profile SET etablissement_inclus = replace(etablissement_inclus,' ,',',') WHERE etablissement_inclus LIKE '% ,%'; UPDATE rh.t_data_profile SET etablissement_inclus = replace(etablissement_inclus,' ,',',') WHERE etablissement_inclus LIKE '% ,%'; UPDATE rh.t_data_profile SET etablissement_inclus = replace(etablissement_inclus,', ',',') WHERE etablissement_inclus LIKE '%, %'; UPDATE rh.t_data_profile SET etablissement_inclus = replace(etablissement_inclus,', ',',') WHERE etablissement_inclus LIKE '%, %'; UPDATE rh.t_data_profile SET etablissement_exclus = trim(etablissement_exclus); UPDATE rh.t_data_profile SET etablissement_exclus = replace(etablissement_exclus,' ,',',') WHERE etablissement_exclus LIKE '% ,%'; UPDATE rh.t_data_profile SET etablissement_exclus = replace(etablissement_exclus,' ,',',') WHERE etablissement_exclus LIKE '% ,%'; UPDATE rh.t_data_profile SET etablissement_exclus = replace(etablissement_exclus,', ',',') WHERE etablissement_exclus LIKE '%, %'; UPDATE rh.t_data_profile SET etablissement_exclus = replace(etablissement_exclus,', ',',') WHERE etablissement_exclus LIKE '%, %'; UPDATE rh.t_data_profile SET service_inclus = trim(service_inclus); UPDATE rh.t_data_profile SET service_inclus = replace(service_inclus,' ,',',') WHERE service_inclus LIKE '% ,%'; UPDATE rh.t_data_profile SET service_inclus = replace(service_inclus,' ,',',') WHERE service_inclus LIKE '% ,%'; UPDATE rh.t_data_profile SET service_inclus = replace(service_inclus,', ',',') WHERE service_inclus LIKE '%, %'; UPDATE rh.t_data_profile SET service_inclus = replace(service_inclus,', ',',') WHERE service_inclus LIKE '%, %'; UPDATE rh.t_data_profile SET service_exclus = trim(service_exclus); UPDATE rh.t_data_profile SET service_exclus = replace(service_exclus,' ,',',') WHERE service_exclus LIKE '% ,%'; UPDATE rh.t_data_profile SET service_exclus = replace(service_exclus,' ,',',') WHERE service_exclus LIKE '% ,%'; UPDATE rh.t_data_profile SET service_exclus = replace(service_exclus,', ',',') WHERE service_exclus LIKE '%, %'; UPDATE rh.t_data_profile SET service_exclus = replace(service_exclus,', ',',') WHERE service_exclus LIKE '%, %'; UPDATE rh.t_data_profile SET statut_inclus = trim(statut_inclus); UPDATE rh.t_data_profile SET statut_inclus = replace(statut_inclus,' ,',',') WHERE statut_inclus LIKE '% ,%'; UPDATE rh.t_data_profile SET statut_inclus = replace(statut_inclus,' ,',',') WHERE statut_inclus LIKE '% ,%'; UPDATE rh.t_data_profile SET statut_inclus = replace(statut_inclus,', ',',') WHERE statut_inclus LIKE '%, %'; UPDATE rh.t_data_profile SET statut_inclus = replace(statut_inclus,', ',',') WHERE statut_inclus LIKE '%, %'; UPDATE rh.t_data_profile SET statut_exclus = trim(statut_exclus); UPDATE rh.t_data_profile SET statut_exclus = replace(statut_exclus,' ,',',') WHERE statut_exclus LIKE '% ,%'; UPDATE rh.t_data_profile SET statut_exclus = replace(statut_exclus,' ,',',') WHERE statut_exclus LIKE '% ,%'; UPDATE rh.t_data_profile SET statut_exclus = replace(statut_exclus,', ',',') WHERE statut_exclus LIKE '%, %'; UPDATE rh.t_data_profile SET statut_exclus = replace(statut_exclus,', ',',') WHERE statut_exclus LIKE '%, %'; -- Génération des oids sur les profils UPDATE rh.t_data_profile SET service_id_array = subview.service_id_array FROM ( SELECT t_data_profile.oid, base.cti_array_accum(t_services.oid) AS service_id_array FROM rh.t_data_profile LEFT JOIN rh.t_services ON (t_services.code LIKE ANY(string_to_array(replace(t_data_profile.service_inclus,'*','%'),',')) OR t_data_profile.service_inclus = '' OR t_data_profile.service_inclus IS NULL) LEFT JOIN rh.t_services t_services_exclus ON t_data_profile.service_exclus <> '' AND t_services_exclus.code LIKE ANY(string_to_array(replace(t_data_profile.service_exclus,'*','%'),',')) AND t_services.oid = t_services_exclus.oid WHERE t_services_exclus.oid IS NULL GROUP BY 1 )subview WHERE subview.oid = t_data_profile.oid ; UPDATE rh.t_data_profile SET statut_id_array = subview.statut_id_array FROM ( SELECT t_data_profile.oid, base.cti_array_accum(t_statuts.oid) AS statut_id_array FROM rh.t_data_profile LEFT JOIN rh.t_statuts ON (t_statuts.code LIKE ANY(string_to_array(replace(t_data_profile.statut_inclus,'*','%'),',')) OR t_data_profile.statut_inclus = '' OR t_data_profile.statut_inclus IS NULL) LEFT JOIN rh.t_statuts t_statuts_exclus ON t_data_profile.statut_exclus <> '' AND t_statuts_exclus.code LIKE ANY(string_to_array(replace(t_data_profile.statut_exclus,'*','%'),',')) AND t_statuts.oid = t_statuts_exclus.oid WHERE t_statuts_exclus.oid IS NULL GROUP BY 1 )subview WHERE subview.oid = t_data_profile.oid ; UPDATE rh.t_data_profile SET etablissement_id_array = subview.etablissement_id_array FROM ( SELECT t_data_profile.oid, base.cti_array_accum(t_etablissements.oid) AS etablissement_id_array FROM rh.t_data_profile LEFT JOIN rh.t_etablissements ON (t_etablissements.code LIKE ANY(string_to_array(replace(t_data_profile.etablissement_inclus,'*','%'),',')) OR t_data_profile.etablissement_inclus = '' OR t_data_profile.etablissement_inclus IS NULL) LEFT JOIN rh.t_etablissements t_etablissements_exclus ON t_data_profile.etablissement_exclus <> '' AND t_etablissements_exclus.code LIKE ANY(string_to_array(replace(t_data_profile.etablissement_exclus,'*','%'),',')) AND t_etablissements.oid = t_etablissements_exclus.oid WHERE t_etablissements_exclus.oid IS NULL GROUP BY 1 )subview WHERE subview.oid = t_data_profile.oid ; -- Actualisation des schémas DROP TABLE IF EXISTS w_tables; CREATE TEMP TABLE w_tables AS SELECT schemaname, tablename FROM pg_tables WHERE schemaname LIKE 'rh%' AND tablename IN ('p_oids','p_indicateurs_cumules'); DROP TABLE IF EXISTS w_views; CREATE TEMP TABLE w_views AS SELECT schemaname, viewname, definition FROM pg_views WHERE schemaname LIKE 'rh%'; -- création des schémas _sqlcmd = 'SELECT t_data_profile.code, ''CREATE SCHEMA IF NOT EXISTS rh_DATA_PROFILE_'' || t_data_profile.code FROM rh.t_data_profile WHERE 1=1 AND CASE WHEN trim('''||_in_data_profile_code||''') = '''' THEN true ELSE t_data_profile.code = trim('''||_in_data_profile_code||''') END AND t_data_profile.code <> '''''; OPEN _cursor FOR EXECUTE _sqlcmd; FETCH _cursor INTO _sqlobject, _tosqlcmd; WHILE FOUND LOOP BEGIN --RAISE NOTICE 'Schema = %',_sqlobject; --RAISE NOTICE 'SQL %' , substr(_tosqlcmd,1,100); EXECUTE _tosqlcmd; EXCEPTION WHEN others THEN RAISE NOTICE 'Erreur %' , _tosqlcmd; END; FETCH _cursor INTO _sqlobject, _tosqlcmd; END LOOP; CLOSE _cursor; -- création des fichiers OIDS _sqlcmd = 'SELECT from_tablename, ''CREATE TABLE rh_DATA_PROFILE_'' || dataprofile_code || ''.'' || from_tablename || '' AS SELECT * FROM rh.'' || from_tablename || '' LIMIT 0'' FROM ( SELECT ''p_oids'' AS from_tablename, t_data_profile.code AS dataprofile_code FROM rh.t_data_profile UNION SELECT ''p_indicateurs_cumules'' AS from_tablename, t_data_profile.code AS dataprofile_code FROM rh.t_data_profile ) subview LEFT JOIN w_tables ON tablename = from_tablename AND schemaname ILIKE ''rh_DATA_PROFILE_'' || dataprofile_code WHERE tablename IS NULL'; OPEN _cursor FOR EXECUTE _sqlcmd; FETCH _cursor INTO _sqlobject, _tosqlcmd; WHILE FOUND LOOP BEGIN --RAISE NOTICE 'Schema = %',_sqlobject; --RAISE NOTICE 'SQL %' , substr(_tosqlcmd,1,100); EXECUTE _tosqlcmd; EXCEPTION WHEN others THEN RAISE NOTICE 'Erreur %' , _tosqlcmd; END; FETCH _cursor INTO _sqlobject, _tosqlcmd; END LOOP; CLOSE _cursor; -- recréation des vues dans un schema utilisateur _sqlcmd = 'SELECT w_views.viewname, t_data_profile.code, ''DROP VIEW IF EXISTS '' || w_views.schemaname || ''_DATA_PROFILE_'' || t_data_profile.code || ''.'' || w_views.viewname || ''; '' || ''CREATE VIEW '' || w_views.schemaname || ''_DATA_PROFILE_'' || t_data_profile.code || ''.'' || w_views.viewname || '' AS '' || w_views.definition, COALESCE(''DROP VIEW IF EXISTS '' || w_views_deja.schemaname || ''.'' || w_views_deja.viewname || ''; '' || ''CREATE VIEW '' || w_views_deja.schemaname || ''.'' || w_views_deja.viewname || '' AS '' || w_views_deja.definition,'''') FROM w_views JOIN rh.t_data_profile ON t_data_profile.code <> '''' LEFT JOIN w_views w_views_deja ON w_views.viewname = w_views_deja.viewname AND w_views_deja.schemaname ILIKE (''rh_DATA_PROFILE_'' || t_data_profile.code) WHERE w_views.schemaname = ''rh'''; --RAISE NOTICE 'SQL %' , _sqlcmd; OPEN _cursor FOR EXECUTE _sqlcmd; FETCH _cursor INTO _sqlobject, _data_profile_code, _tosqlcmd, _tosqlcmd_deja; WHILE FOUND LOOP BEGIN -- Remplacement accès table p_indicateurs_cumules _tosqlcmd = replace(_tosqlcmd, 'rh.p_indicateurs_cumules', 'rh_data_profile_' || _data_profile_code || '.p_indicateurs_cumules' ); -- Remplacement accès table t_data_profile _tosqlcmd = replace(_tosqlcmd, 'rh.t_data_profile', '(rh.t_data_profile JOIN rh.t_data_profile t_data_profile_2 ON t_data_profile_2.oid = t_data_profile.oid AND t_data_profile_2.code::text = ''' || _data_profile_code || '''::text)' ); -- Remplacement accès table t_services _tosqlcmd = replace(_tosqlcmd, 'rh.t_services', '(rh.t_services JOIN rh.t_data_profile t_data_profile_service ON t_data_profile_service.code::text = ''' || _data_profile_code || '''::text AND t_services.oid = ANY (t_data_profile_service.service_id_array))' ); -- Remplacement accès table t_statuts _tosqlcmd = replace(_tosqlcmd, 'rh.t_statuts', '(rh.t_statuts JOIN rh.t_data_profile t_data_profile_statut ON t_data_profile_statut.code::text = ''' || _data_profile_code || '''::text AND t_statuts.oid = ANY (t_data_profile_statut.statut_id_array))' ); -- Remplacement accès table t_etablissements _tosqlcmd = replace(_tosqlcmd, 'rh.t_etablissements', '(rh.t_etablissements JOIN rh.t_data_profile t_data_profile_etablissement ON t_data_profile_etablissement.code::text = ''' || _data_profile_code || '''::text AND t_etablissements.oid = ANY (t_data_profile_etablissement.etablissement_id_array))' ); -- Remplacement accès table p_profils _tosqlcmd = replace(_tosqlcmd, 'rh.p_profils', '(rh.p_profils JOIN rh.t_data_profile t_data_profile_profil ON t_data_profile_profil.code::text = ''' || _data_profile_code || '''::text AND p_profils.service_id = ANY (t_data_profile_profil.service_id_array) AND p_profils.statut_id = ANY (t_data_profile_profil.statut_id_array) )' ); -- Remplacement accès table p_oids _tosqlcmd = replace(_tosqlcmd, 'rh.p_oids', 'rh_DATA_PROFILE_' || _data_profile_code || '.p_oids' ); IF lower(_tosqlcmd) <> lower(_tosqlcmd_deja) THEN --RAISE NOTICE 'Vue = %',_sqlobject || ' (' || _data_profile_code || ')'; --RAISE NOTICE 'SQL %' , _tosqlcmd; --RAISE NOTICE 'SQL %' , _tosqlcmd_deja; EXECUTE _tosqlcmd; END IF; EXCEPTION WHEN others THEN RAISE NOTICE 'Erreur %' , substr(_tosqlcmd,1,100); END; FETCH _cursor INTO _sqlobject, _data_profile_code, _tosqlcmd, _tosqlcmd_deja; END LOOP; CLOSE _cursor; -- Alimentation des oids par profil _tosqlcmd_base = 'TRUNCATE rh.p_oids; INSERT INTO rh.p_oids (code_table, oid) SELECT code_table, oid FROM rh.p_oids WHERE code_table = ''anciennetes_annee''; INSERT INTO rh.p_oids (code_table, oid) SELECT code_table, oid FROM rh.p_oids WHERE code_table = ''situations_famille''; INSERT INTO rh.p_oids (code_table, oid) SELECT code_table, oid FROM rh.p_oids WHERE code_table = ''nationalites''; INSERT INTO rh.p_oids (code_table, oid) SELECT code_table, oid FROM rh.p_oids WHERE code_table = ''codes_postaux''; INSERT INTO rh.p_oids (code_table, oid) SELECT code_table, oid FROM rh.p_oids WHERE code_table = ''departements''; INSERT INTO rh.p_oids (code_table, oid) SELECT code_table, oid FROM rh.p_oids WHERE code_table = ''motifs_arret''; INSERT INTO rh.p_oids (code_table, oid) SELECT code_table, oid FROM rh.p_oids WHERE code_table = ''precisions_motif_arret''; INSERT INTO rh.p_oids (code_table, oid) SELECT code_table, oid FROM rh.p_oids WHERE code_table = ''rubriques''; INSERT INTO rh.p_oids (code_table, oid) SELECT code_table, oid FROM rh.p_oids WHERE code_table = ''organismes_cotisation''; INSERT INTO rh.p_oids (code_table, oid) SELECT code_table, oid FROM rh.p_oids WHERE code_table = ''motifs_visite''; INSERT INTO rh.p_oids (code_table, oid) SELECT code_table, oid FROM rh.p_oids WHERE code_table = ''accident_circonstance''; INSERT INTO rh.p_oids (code_table, oid) SELECT code_table, oid FROM rh.p_oids WHERE code_table = ''accident_lieu''; INSERT INTO rh.p_oids (code_table, oid) SELECT code_table, oid FROM rh.p_oids WHERE code_table = ''accident_nature''; INSERT INTO rh.p_oids (code_table, oid) SELECT code_table, oid FROM rh.p_oids WHERE code_table = ''accident_siege''; INSERT INTO rh.p_oids (code_table, oid) SELECT code_table, oid FROM rh.p_oids WHERE code_table = ''formations''; INSERT INTO rh.p_oids (code_table, oid) SELECT code_table, oid FROM rh.p_oids WHERE code_table = ''compte''; INSERT INTO rh.p_oids (code_table, oid) SELECT code_table, oid FROM rh.p_oids WHERE code_table = ''planning_type_absence''; INSERT INTO rh.p_oids (code_table, oid) SELECT ''salaries'', p_profil_contrat_mois.salarie_id FROM rh.p_profil_contrat_mois JOIN rh.p_profils ON p_profil_contrat_mois.profil_id = p_profils.oid GROUP BY 1,2; INSERT INTO rh.p_oids (code_table, oid) SELECT ''services'', p_profils.service_id FROM rh.p_profils GROUP BY 1,2; INSERT INTO rh.p_oids (code_table, oid) SELECT ''qualifications'', p_profils.qualification_id FROM rh.p_profils GROUP BY 1,2; INSERT INTO rh.p_oids (code_table, oid) SELECT ''types_temps_travail'', p_profils.type_temps_travail_id FROM rh.p_profils GROUP BY 1,2; INSERT INTO rh.p_oids (code_table, oid) SELECT ''types_contrat'', p_profils.type_contrat_id FROM rh.p_profils GROUP BY 1,2; INSERT INTO rh.p_oids (code_table, oid) SELECT ''specialites'', p_profils.specialite_id FROM rh.p_profils GROUP BY 1,2; INSERT INTO rh.p_oids (code_table, oid) SELECT ''categories_socio_professionnelle'', p_profils.categorie_socio_professionnelle_id FROM rh.p_profils GROUP BY 1,2; INSERT INTO rh.p_oids (code_table, oid) SELECT ''statuts'', p_profils.statut_id FROM rh.p_profils GROUP BY 1,2; INSERT INTO rh.p_oids (code_table, oid) SELECT ''codes_emploi'', p_profils.code_emploi_id FROM rh.p_profils GROUP BY 1,2; INSERT INTO rh.p_oids (code_table, oid) SELECT ''motifs_debut_contrat'', p_profils.motif_debut_id FROM rh.p_profils GROUP BY 1,2; INSERT INTO rh.p_oids (code_table, oid) SELECT ''motifs_fin_contrat'', p_profils.motif_fin_id FROM rh.p_profils GROUP BY 1,2; INSERT INTO rh.p_oids (code_table, oid) SELECT ''sections_analytiques_paie'', p_profils.section_analytique_paie_id FROM rh.p_profils GROUP BY 1,2; INSERT INTO rh.p_oids (code_table, oid) SELECT ''sections_analytiques'', p_profils.section_analytique_id FROM rh.p_profils GROUP BY 1,2; INSERT INTO rh.p_oids (code_table, oid) SELECT ''grilles'', p_profils.grille_id FROM rh.p_profils GROUP BY 1,2; INSERT INTO rh.p_oids (code_table, oid) SELECT ''grilles_groupes'', p_profils.grille_groupe_id FROM rh.p_profils GROUP BY 1,2; INSERT INTO rh.p_oids (code_table, oid) SELECT ''groupes_cotisant'', p_profils.groupe_cotisant_id FROM rh.p_profils GROUP BY 1,2; INSERT INTO rh.p_oids (code_table, oid) SELECT ''societes_interim'', p_profils.societe_interim_id FROM rh.p_profils GROUP BY 1,2; INSERT INTO rh.p_oids (code_table, oid) SELECT ''lettre_budgetaire'', p_profils.lettre_budgetaire_id FROM rh.p_profils GROUP BY 1,2; INSERT INTO rh.p_oids (code_table, oid) SELECT ''compte_salarie'', p_profils.compte_salarie_id FROM rh.p_profils GROUP BY 1,2; INSERT INTO rh.p_oids (code_table, oid) SELECT ''categorie_conge'', p_profils.categorie_conge_id FROM rh.p_profils GROUP BY 1,2; INSERT INTO rh.p_oids (code_table, oid) SELECT ''commission_paritaire'', p_profils.commission_paritaire_id FROM rh.p_profils GROUP BY 1,2; INSERT INTO rh.p_oids (code_table, oid) SELECT ''filiere'', p_profils.filiere_id FROM rh.p_profils GROUP BY 1,2; INSERT INTO rh.p_oids (code_table, oid) SELECT ''cadre_emploi'', p_profils.cadre_emploi_id FROM rh.p_profils GROUP BY 1,2; INSERT INTO rh.p_oids (code_table, oid) SELECT ''categorie_statutaire'', p_profils.categorie_statutaire_id FROM rh.p_profils GROUP BY 1,2; INSERT INTO rh.p_oids (code_table, oid) SELECT ''unite_fonctionnelle'', p_profils.unite_fonctionnelle_id FROM rh.p_profils GROUP BY 1,2; '; -- recréation des vues dans un schema utilisateur _sqlcmd = 'SELECT t_data_profile.code FROM rh.t_data_profile WHERE t_data_profile.code <> '''''; --RAISE NOTICE 'SQL %' , _sqlcmd; OPEN _cursor FOR EXECUTE _sqlcmd; FETCH _cursor INTO _data_profile_code; WHILE FOUND LOOP BEGIN --RAISE NOTICE 'SQL %' , _data_profile_code; --RAISE NOTICE 'SQL %' , _tosqlcmd_base; -- Remplacement accès table p_oids _tosqlcmd = replace(_tosqlcmd_base, 'INSERT INTO rh.p_oids', 'INSERT INTO rh_DATA_PROFILE_' || _data_profile_code || '.p_oids' ); _tosqlcmd = replace(_tosqlcmd, 'TRUNCATE rh.p_oids', 'TRUNCATE rh_DATA_PROFILE_' || _data_profile_code || '.p_oids' ); -- Remplacement accès table p_profils _tosqlcmd = replace(_tosqlcmd, 'rh.p_profils', '(rh.p_profils JOIN rh.t_data_profile ON t_data_profile.code::text = ''' || _data_profile_code || '''::text AND p_profils.service_id = ANY (t_data_profile.service_id_array) AND p_profils.statut_id = ANY (t_data_profile.statut_id_array) )' ); -- Remplacement accès table t_etablissements _tosqlcmd = replace(_tosqlcmd, 'rh.t_etablissements', '(rh.t_etablissements JOIN rh.t_data_profile ON t_data_profile.code::text = ''' || _data_profile_code || '''::text AND t_etablissements.oid = ANY (t_data_profile.etablissement_id_array))' ); --RAISE NOTICE 'SQL %' , _tosqlcmd; EXECUTE _tosqlcmd; EXCEPTION WHEN others THEN RAISE NOTICE 'Erreur %' , substr(_tosqlcmd,1,100); END; FETCH _cursor INTO _data_profile_code; END LOOP; CLOSE _cursor; return 'OK'; END;