-- 1/3 : Création de la table temporaire DROP TABLE IF EXISTS w_dbsetup ; CREATE TEMP TABLE w_dbsetup AS WITH flatSeries as ( SELECT oid, cast(jsonb_array_elements(replace('[' || serie_id || ']', '|', ',')::jsonb)->>'pos' as bigint) as position, cast(jsonb_array_elements(replace('[' || serie_id || ']', '|', ',')::jsonb)->>'id' as bigint) as id FROM rh.t_indicateur_serie WHERE serie_id != '{}' AND serie_id != '' ORDER BY oid, position ), flatCodes as (SELECT flatSeries.oid, array_agg(position::text || ':' || t_indicateur_serie.code::text) as codes FROM flatSeries LEFT JOIN rh.t_indicateur_serie on t_indicateur_serie.oid = id GROUP BY 1) SELECT t_indicateur_serie.code, coalesce(t_indicateurs.code, '') as indicateur_code, t_indicateur_serie.name, t_indicateur_serie.color, t_indicateur_serie.formula, t_indicateur_serie.calc, t_indicateur_serie.total, t_indicateur_serie.format, case when array_agg(DISTINCT t_indicateur_condition.external_code2) = ARRAY[null] then ARRAY[]::text[] else array_agg(DISTINCT t_indicateur_condition.external_code2) end as external_code2, CASE WHEN flatCodes.codes = ARRAY[null] THEN '{}'::text[] ELSE flatCodes.codes::text[] END as serie_code FROM rh.t_indicateur_serie LEFT JOIN rh.t_indicateurs ON t_indicateurs.oid = indicateur_id LEFT JOIN rh.t_indicateur_condition ON ARRAY[t_indicateur_condition.oid] <@ t_indicateur_serie.condition_id LEFT JOIN flatCodes on flatCodes.oid = t_indicateur_serie.oid GROUP BY 1,2,3,4,5,6,7,8, flatCodes.codes ORDER BY 2,1 LIMIT 0 ; -- 2/3 : Peuplement de la table temporaire INSERT INTO w_dbsetup( code, indicateur_code, name, color, formula, calc, total, format, external_code2, serie_code ) VALUES ('CTI_ENTSORF', '', 'Nombre entrees et sorties Femmes', '#d19aed', '[1] + [2]', 't', 'f', '', '{""}', '{"1:CTI_NVSALF", "2:CTI_DEPSALF"}'), ('CTI_ENTSORH', '', 'Nombre entrees et sorties Hommes', '#7b53e8', '[1] + [2]', 't', 'f', '', '{""}', '{"1:CTI_NVSALH", "2:CTI_DEPSALH"}'), ('CTI_HSUPF', '', 'Heures supplementaires Femmes', '#d19aed', '', 'f', 'f', '', '{"CTI_SEXE#DT#2"}', '{}'), ('CTI_HSUPH', '', 'Heures supplementaires Hommes', '#7b53e8', '', 'f', 'f', '', '{"CTI_SEXE#DT#1"}', '{}'), ('CTI_TAUXSTAT', '', 'Taux par statut', '', '([1] / [2])', 't', 'f', '0.00%', '{""}', '{"1:CTI_TOTSAL", "2:CTI_TOTSALF"}'), ('CTI_TOF', '', 'Turn Over Femmes', '#d19aed', '([1]/2) / [2]', 't', 'f', '0.00%', '{""}', '{"1:CTI_ENTSORF", "2:CTI_EFFDF"}'), ('CTI_TOH', '', 'Turn Over Hommes', '#7b53e8', '([1]/2) / [2]', 't', 'f', '0.00%', '{""}', '{"1:CTI_ENTSORH", "2:CTI_EFFDH"}'), ('CTI_MS', 'CTIMTMASSE', 'Masse salariale', '#7b53e8', '', 'f', 'f', '', '{""}', '{}'), ('CTI_MSF', 'CTIMTMASSE', 'Masse salariale Femmes', '#d19aed', '', 'f', 'f', '', '{"CTI_SEXE#DT#2"}', '{}'), ('CTI_MSH', 'CTIMTMASSE', 'Masse salariale Hommes', '#7b53e8', '', 'f', 'f', '', '{"CTI_SEXE#DT#1"}', '{}'), ('CTI_EFFDF', 'CTI_EFFDJPER', 'Effectifs dernier jour Femmes', '#d19aed', '', 'f', 'f', '', '{"CTI_SEXE#DT#2"}', '{}'), ('CTI_EFFDH', 'CTI_EFFDJPER', 'Effectifs dernier jour Hommes', '#7b53e8', '', 'f', 'f', '', '{"CTI_SEXE#DT#1"}', '{}'), ('CTI_FEMMES', 'CTI_NBSALCNT', 'Femmes', '#d19aed', '', 'f', 'f', '', '{"CTI_SEXE#DT#2"}', '{}'), ('CTI_HOMMES', 'CTI_NBSALCNT', 'Hommes', '#7b53e8', '', 'f', 'f', '', '{"CTI_SEXE#DT#1"}', '{}'), ('CTI_TOTSAL', 'CTI_NBSALCNT', 'Total salaries', '', '', 'f', 'f', '', '{""}', '{}'), ('CTI_TOTSALF', 'CTI_NBSALCNT', 'Total Salaries fin annee', '', '', 'f', 't', '', '{""}', '{}'), ('CTI_NVSALF', 'CTI_NOUVSALS', 'Nouveaux salaries Femmes', '#d19aed', '', 'f', 'f', '', '{"CTI_SEXE#DT#2"}', '{}'), ('CTI_NVSALH', 'CTI_NOUVSALS', 'Nouveaux salaries Hommes', '#7b53e8', '', 'f', 'f', '', '{"CTI_SEXE#DT#1"}', '{}'), ('CTI_DEPSALF', 'CTI_SALPARTISSP', 'Departs salaries Femmes', '#d19aed', '', 'f', 'f', '', '{"CTI_SEXE#DT#2"}', '{}'), ('CTI_DEPSALH', 'CTI_SALPARTISSP', 'Departs salaries Hommes', '#7b53e8', '', 'f', 'f', '', '{"CTI_SEXE#DT#1"}', '{}') ; -- 3/3 : Màj de la table iCTI SELECT rh.cti_reorganize_indicateur_condition(); TRUNCATE rh.t_indicateur_serie; INSERT INTO rh.t_indicateur_serie(indicateur_id, condition_id, name, color, formula, calc, serie_id, total, format, code) SELECT coalesce(t_indicateurs.oid, 0), case when array_agg(DISTINCT t_indicateur_condition.oid) = ARRAY[NULL]::bigint[] then ARRAY[]::bigint[] else array_agg(DISTINCT t_indicateur_condition.oid) end, w_dbsetup.name, w_dbsetup.color, w_dbsetup.formula, w_dbsetup.calc, case when array_agg(DISTINCT rec.oid) = ARRAY[NULL]::bigint[] then ARRAY[]::bigint[] else array_agg(DISTINCT rec.oid) end, w_dbsetup.total, w_dbsetup.format, w_dbsetup.code FROM w_dbsetup LEFT JOIN rh.t_indicateurs ON t_indicateurs.code = w_dbsetup.indicateur_code LEFT JOIN rh.t_indicateur_condition ON ARRAY[t_indicateur_condition.external_code2] <@ w_dbsetup.external_code2 LEFT JOIN rh.t_indicateur_serie as rec ON ARRAY[rec.code] <@ w_dbsetup.serie_code GROUP BY 1,3,4,5,6,8,9,10 ; WITH series_id as ( SELECT w_dbsetup.code, split_part(unnest(w_dbsetup.serie_code), ':', 1) as pos, split_part(unnest(w_dbsetup.serie_code), ':', 2) as serie_code FROM w_dbsetup ), full_series as ( SELECT series_id.code, coalesce(string_agg('{"pos": ' || pos || ', "id": ' || t_indicateur_serie.oid || '}', '|'), '') as serie_id FROM series_id LEFT JOIN rh.t_indicateur_serie ON t_indicateur_serie.code = serie_code GROUP BY 1 ) UPDATE rh.t_indicateur_serie SET serie_id = CASE WHEN full_series.serie_id IS NULL THEN '' ELSE full_series.serie_id END FROM w_dbsetup LEFT JOIN full_series ON full_series.code = w_dbsetup.code WHERE t_indicateur_serie.code = w_dbsetup.code ;