= 100 OR @c03 = 0 then 'TC' else 'TP'||(@c03)::text end as ttt_code
from prod_pleiades.d01v1_perxhx
;
drop table if exists w_cnt_tho
;
create temp table w_cnt_tho as
select
cb as mat,
cb||'-'||(rank() over (partition by cb order by cf))::text as tho_num,
cf::date as date_debut,
coalesce(lead(cf::date) over (partition by cb order by cf) - 1, '20991231'::date) as date_fin,
c07 as tho_code
from prod_pleiades.d01v1_pereta
;
-- Relation 1 pour 1 entre le matricule et la spécialité.
drop table if exists w_cnt_spe
;
create temp table w_cnt_spe as
select
cb as mat,
max(c02)::text AS spe_code -- on enfonce le clou (1 pour 1) par sécurité.
from prod_pleiades.d01v1_perxme
group by 1
;
-- Création table des contrats.
drop table if exists w_cnt
;
create temp table w_cnt as
select
d01v1_perctr.cb as mat,
d01v1_perctr.cb||'-'||rank() over (partition by d01v1_perctr.cb order by d01v1_perctr.cf) as cnt,
d01v1_perctr.cf::date as date_debut,
coalesce(d01v1_perctr.c09::date, '20991231'::date) as date_fin,
d01v1_perctr.c02 as motif_debut,
d01v1_perctr.c08 as motif_fin,
d01v1_perctr.c03 as nature_contrat, -- à concaténer avec le type de contrat
d01v1_perctr.c04 as type_contrat,
d01v1_percdd.c03 as mat_remp
from prod_pleiades.d01v1_perctr
left join prod_pleiades.d01v1_percdd on 1=1
and d01v1_percdd.cb = d01v1_perctr.cb
and d01v1_percdd.cf = d01v1_perctr.cf
;
-- Création table de compte comptables.
drop table if exists w_compte
;
create temp table w_compte as
select
poste,
matricule,
compte,
('20'||periode_imputation)::numeric as periode_imputation,
sous_periode,
periode_origine
from prod_pleiades.a01_compta
where 1=1
and ecriture = 'C'
and compte != '999999999'
group by 1,2,3,4,5,6
;
-- Création d'une table brut de paie
/*drop table if exists w_hp
;
create temp table w_hp as
select
trim(mat) as mat,
mois,
date1 as date_virement,
trim(col1) as sous_periode,
date_debut,
date_fin,
mois != to_char(date_debut, 'YYYYMM')::numeric as regul, -- true quand régulation.
trim(nb1) as rub,
to_number(mnt2, 'SG000000000D00') as base,
to_number(mnt3, 'SG000000000D00') as tx,
to_number(mnt4, 'SG000000000D00') as mt
from prod_pleiades.cti_pfedis01
;*/
-- créer une vue avec ca : vvvvvv
DROP VIEW IF EXISTS public.w_hp
;
CREATE OR REPLACE VIEW public.w_hp AS
select
ctid as hp_ctid,
trim(matricule) as mat,
date_compta::numeric as mois,
date_comptable::date as date_virement,
periode as sous_periode,
debut_periode::date as date_debut,
fin_periode::date as date_fin,
date_compta != to_char(debut_periode, 'YYYYMM')::numeric as regul,
trim(poste) as rub,
nombre as base,
taux as tx,
montant as mt
from prod_pleiades.a01_z_paic
;
-- Créer une table des bulletins.
-- Les rubriques de régulation (en "R") seront affectées systématiquement au 1er bulletin du mois.
DROP TABLE IF EXISTS w_bul
;
CREATE TEMP TABLE w_bul AS
with bul_mois as (
select
mat,
mois,
case when mois = to_char(date_debut, 'YYYYMM')::numeric then date_debut else (mois||'01')::date end as date_debut,
case when mois = to_char(date_debut, 'YYYYMM')::numeric then date_fin else base.cti_last_day((mois||'01')::date) end as date_fin,
count(*) over (partition by mat, mois) as nb_bul_month,
count(case when mois = to_char(date_debut, 'YYYYMM')::numeric then date_debut else null end) as nb_lines_month
from w_hp
group by 1,2,3,4)
--
select
mat||mois||lpad(rank() over (partition by mat, mois order by date_debut), 2, '0') as bul,
*
from bul_mois
where case when nb_lines_month = 0 then nb_bul_month = 1 else true end -- on ne conserve que les bulletins mois qui n'ont aucune ligne sur le mois d'imputation (100% de régul).
;
]]>
= 2009
AND (1!=1
OR w_cnt is not NULL
OR w_cnt_csp is not null
OR w_cnt_emp is not null
OR w_cnt_aff is not null
OR w_cnt_ttt is not null
OR w_bul is not null)
group by 1,4,5,6,7,8,9,10,11,12,13,14,15,16,17
;
-- Associer le dernier contrat aux bulletins hors période de contrat.
/* UPDATE w_evt
SET cnt = subq.cnt,
cnt_date_debut = subq.cnt_date_debut,
cnt_date_fin = subq.cnt_date_fin
FROM (
select
t1.mat,
t1.date_debut,
t1.bul_0,
(max(ARRAY[t2.date_fin::text, t2.cnt::text]))[2] as cnt,
max(t2.date_debut) AS cnt_date_debut,
max(t2.date_fin) AS cnt_date_fin
from w_evt AS t1
left JOIN w_cnt AS t2 on 1=1
and t2.mat = t1.mat
and t2.date_fin < t1.date_debut
and t1.cnt is null
group by 1,2,3
having (max(ARRAY[t2.date_fin::text, t2.cnt::text]))[2] is not null
) AS subq
WHERE 1=1
AND w_evt.mat = subq.mat
AND w_evt.date_debut = subq.date_debut
AND w_evt.bul_0 = subq.bul_0
;*/
]]>
100%
WHEN type_temps_travail_code = 'TC' THEN 100 -- lorsque TC -> 100%
WHEN base.cti_to_number(substr(type_temps_travail_code, 2)) = 0 THEN 1 -- lorsque TP à 0% -> 1%
ELSE base.cti_to_number(substr(type_temps_travail_code, 2)) -- n%
END)::numeric AS pct_temps_travail,
(date_fin - date_debut + 1)::numeric AS duree,
(CASE date_part('month', date_fin)
WHEN 02 THEN CASE WHEN date_part('year', date_fin) IN (2000, 2004, 2008, 2012) THEN 29 ELSE 28 END
WHEN 04 THEN 30
WHEN 06 THEN 30
WHEN 09 THEN 30
WHEN 11 THEN 30
ELSE 31
END)::numeric AS duree_mois
FROM rh.p_contrats_mois
JOIN rh.p_profil_contrat_mois ON p_profil_contrat_mois.contrat_mois_id = p_contrats_mois.oid
JOIN rh.p_profils ON p_profils.oid = p_profil_contrat_mois.profil_id
;
UPDATE rh.p_contrats_mois
SET equivalent_temps_plein = round((duree / duree_mois) * (pct_temps_travail / 100), 7)
FROM maj_etp
WHERE 1=1
AND p_contrats_mois.oid = maj_etp.contrat_mois_id
AND equivalent_temps_plein IS DISTINCT FROM round((duree / duree_mois) * (pct_temps_travail / 100), 7)
;
*/
]]>
= '2008-01-01'
GROUP BY 1,2,3,4
;
-- Associer les visites hors contrat au plus récent existant précédemment (en amont) ...
UPDATE w_visites
SET cnt = subq.cnt
FROM (
select
w_visites.mat,
w_visites.date,
(max(array[w_cnt.date_fin::text, w_cnt.cnt]))[2] as cnt
from w_visites
JOIN w_cnt ON true
AND w_cnt.mat = w_visites.mat
and w_cnt.date_fin < w_visites.date
where w_visites.cnt is null
group by 1,2
) as subq
WHERE true
AND w_visites.mat = subq.mat
AND w_visites.date = subq.date
;
-- ... Puis en aval.
UPDATE w_visites
SET cnt = subq.cnt
FROM (
select
w_visites.mat,
w_visites.date,
(min(array[w_cnt.date_debut::text, w_cnt.cnt]))[2] as cnt
from w_visites
JOIN w_cnt ON true
AND w_cnt.mat = w_visites.mat
and w_visites.date < w_cnt.date_debut
where w_visites.cnt is null
group by 1,2
) as subq
WHERE true
AND w_visites.mat = subq.mat
AND w_visites.date = subq.date
;
-- Peuplement de rh.p_visites_medicales
TRUNCATE rh.p_visites_medicales
;
ALTER SEQUENCE rh.s_visites_medicales RESTART WITH 1
;
INSERT INTO rh.p_visites_medicales(
salarie_id,
contrat_id,
contrat_mois_id,
mois_activite,
date,
motif_visite_id)
SELECT p_salaries.oid,
p_contrats.oid,
p_contrats_mois.oid,
w_visites.mois_activite,
w_visites.date,
t_motifs_visite.oid
FROM w_visites
JOIN rh.p_salaries ON p_salaries.matricule = w_visites.mat
JOIN rh.p_contrats ON p_contrats.numero_contrat = w_visites.cnt
JOIN rh.p_contrats_mois ON true
AND p_contrats_mois.contrat_id = p_contrats.oid
AND w_visites.date between p_contrats_mois.date_debut AND p_contrats_mois.date_fin
JOIN rh.t_motifs_visite ON t_motifs_visite.code_original = w_visites.motif
;
]]>