41637 -- 2013-12-31
;
-- Table des lignes de paies forfait jour (création d'une rubrique 4540 qui n'existe pas dans ces bulletins).
DROP TABLE IF EXISTS w_ligne_fj
;
CREATE TEMP TABLE w_ligne_fj AS
select
ent_id,
bul_id,
'4540'::text as code,
bul_horf::numeric as nombre,
bul_heure_payees::numeric as base
from w_bulletin
where forfait_jour
;
-- Alimentation de la base de la rubrique forfait 1350 avec la valeur de 1363, 1365 ou 3162.
UPDATE w_ligne SET
lig_bas1 = w_ligne_fj.base
FROM w_ligne_fj
WHERE 1=1
AND w_ligne.bul_id = w_ligne_fj.bul_id
AND w_ligne.pla_id = 1350
;
-- Conversion en heures de la base de la rubrique d'absence E/S 2250 lorsqu'il s'agit de forfaits jours car exprimée en jours.
UPDATE w_ligne SET
lig_bas1 = (lig_bas1 / 20.67) * 151.67
FROM w_ligne_fj
WHERE 1=1
AND w_ligne.bul_id = w_ligne_fj.bul_id
AND w_ligne.pla_id = 2250
;
CREATE INDEX w_bulletin_1 ON w_bulletin USING btree (ent_id)
;
CREATE INDEX w_bulletin_2 ON w_bulletin USING btree (bul_id)
;
DROP TABLE IF EXISTS w_h_coeff
;
CREATE TEMP TABLE w_h_coeff AS
SELECT
to_timestamp((coe_du - 25567) * 86400)::date AS date_debut,
CASE WHEN lead(coe_du) over w is null THEN '2099-12-31'::date ELSE to_timestamp((coalesce(lead(coe_du) over w - 1, 99999) - 25567) * 86400)::date END as date_fin,
h_coeff.*
FROM prod_rhplace.h_coeff
JOIN w_ets ON w_ets.ent_id = h_coeff.ent_id
window w as (partition by sal_matr order by coe_du)
;
DROP TABLE IF EXISTS w_h_es
;
CREATE TEMP TABLE w_h_es AS
SELECT
to_timestamp((e_s_date - 25567) * 86400)::date AS date_debut,
CASE WHEN e_s_dates = 0 THEN '2099-12-31'::date ELSE to_timestamp((e_s_dates - 25567) * 86400)::date END AS date_fin,
h_es.*
FROM prod_rhplace.h_es
JOIN w_ets ON w_ets.ent_id = h_es.ent_id
;
-- Statuts
DROP TABLE IF EXISTS w_h_stprof
;
CREATE TEMP TABLE w_h_stprof AS
SELECT
to_timestamp((stp_date - 25567) * 86400)::date AS date_debut,
CASE WHEN lead(stp_date) over w is null THEN '2099-12-31'::date ELSE to_timestamp((coalesce(lead(stp_date) over w - 1, 99999) - 25567) * 86400)::date END as date_fin,
h_stprof.*
FROM prod_rhplace.h_stprof
JOIN w_ets ON w_ets.ent_id = h_stprof.ent_id
window w as (partition by sal_matr order by stp_date)
;
DROP TABLE IF EXISTS w_rub
;
CREATE TEMP TABLE w_rub AS
with rub_per as (
select
pla_id,
pla_type,
pla_int,
pla_dval,
coalesce(nullif(pla_tot, ''), 'N') as pla_tot, -- par défaut on met 'N'.
coalesce(lead(pla_dval) over (partition by pla_id order by pla_dval) - 1, 99999) as pla_fval
from prod_rhplace.plap)
,rub_filter as (
select *
from rub_per
where false
OR 41638 between pla_dval and pla_fval -- 41638 = 2014-01-01
OR pla_dval >= 41638)
,clustering as (
select
pla_id,
pla_type,
pla_int,
pla_dval,
pla_fval,
pla_tot,
case when pla_tot != coalesce(lag(pla_tot) over w, 'C') then true else null end as new_cluster
from rub_filter
window w as (partition by pla_id order by pla_dval))
,assigned_clustering as (
select
*
, count(new_cluster) over (
partition by pla_id
order by pla_dval
rows unbounded preceding
) as cluster_id
from clustering)
,tmp_rubs as (
select
pla_id,
pla_type,
pla_int,
pla_tot,
min(pla_dval) as pla_dval,
max(pla_fval) as pla_fval
from assigned_clustering
group by 1,2,3,4,cluster_id)
select
pla_id,
pla_type,
pla_int,
pla_tot,
case when count(*) over (partition by pla_id) > 1
then
case when row_number() over (partition by pla_id order by pla_dval desc) = 1
then pla_id
else pla_id||'_'||to_char(to_timestamp((pla_dval - 25567) * 86400)::date, 'DD/MM/YYYY')
end
else pla_id end as pla_code,
pla_id||'_'||to_char(to_timestamp((pla_dval - 25567) * 86400)::date, 'YYYYMMDD') as pla_code_original,
pla_dval,
pla_fval
from tmp_rubs
;
]]>
0
AND cpt_cle NOT IN (SELECT code_original FROM rh.t_compte WHERE code_original IS NOT NULL)
GROUP BY 1,2,3,4
;
-- [NON] Màj des sociétés d'interim
-- Màj des grilles
INSERT INTO rh.t_grilles(code_original, code, texte, texte_court)
SELECT cat_id, cat_id, cat_lib, substr(cat_lib, 1, 50)
FROM prod_rhplace.ar_categ
JOIN w_ets ON w_ets.ent_id = ar_categ.ent_id
WHERE cat_id NOT IN (SELECT code_original FROM rh.t_grilles)
GROUP BY 1,2,3,4
;
-- Màj des groupes de grilles
INSERT INTO rh.t_grilles_groupes(code_original, code, texte, texte_court)
SELECT coe_val, coe_val, coe_val, coe_val
FROM w_h_coeff
WHERE coe_val NOT IN (SELECT code_original FROM rh.t_grilles_groupes)
GROUP BY 1
;
-- [NON] Màj des motifs d'arret
-- [NON] Màj des précisions du motif d'arrêt
-- [NON] Màj des motifs de visite médicale
-- [NON] Màj des circonstances d'accident du travail
-- [NON] Màj des lieux d'accident du travail
-- [NON] Màj de la nature de l'accident du travail
-- [NON] Màj des sièges d'accident du travail
-- [NON] Màj des listes de formations
-- [NON] Màj des sections analytiques compta
-- [NON] Màj des sections analytiques paie
]]>
0 THEN sal_val_nom ELSE sal_naiss END AS nom,
sal_prenom AS prenom,
v_sal_dnaiss AS date_naissance,
CASE WHEN substr(sal_noss, 1, 1) = 1 THEN 'M' ELSE 'F' END AS sexe,
salarie.sal_matr AS matricule,
salarie.sal_matr AS code,
salarie.sal_matr AS code_original,
max(coalesce(t_entreprises.oid, 0)) AS entreprise_id,
max(coalesce(t_nationalites.oid, 0)) AS nationalite_id,
max(coalesce(t_codes_postaux.oid, 0)) AS code_postal_id,
sal_naiss AS nom_naissance,
max(coalesce(t_situations_famille.oid, 0)) AS situation_famille_id,
((max(ARRAY[w_profils.date_fin::text, w_profils.profil_id::text]))[2])::bigint AS profil_id, -- dernier profil salarié.
max(h_cnt_trav.date_debut) AS date_debut, -- date de début du dernier contrat.
max(h_cnt_trav.date_fin) AS date_fin, -- date de fin du dernier contrat.
salarie.v_sal_dat_cemp AS date_entree_ets,
max(h_cnt_trav.date_fin) AS date_sortie_ets,
-- Champs dédiés au public.
'1900-01-01'::date AS date_entree_fp,
'1900-01-01'::date AS date_entree_fph,
0 AS no_adeli,
0 AS code_cotisation_id,
0 AS matricule_retraite,
salarie.sal_noss||salarie.sal_cless AS nir
FROM w_salarie AS salarie
JOIN w_ets ON w_ets.eta_id = salarie.eta_id
JOIN w_cnt AS h_cnt_trav ON 1=1
AND h_cnt_trav.ent_id = salarie.ent_id
AND h_cnt_trav.sal_matr = salarie.sal_matr
JOIN w_profils on w_profils.numero_contrat = h_cnt_trav.numero_contrat
LEFT JOIN rh.t_codes_postaux ON t_codes_postaux.code = salarie.sal_cp
LEFT JOIN rh.t_situations_famille ON t_situations_famille.code_original = salarie.fam_id
LEFT JOIN rh.t_entreprises ON t_entreprises.code_original = salarie.ent_id
LEFT JOIN rh.t_nationalites ON t_nationalites.code_original = salarie.sal_cod_pays
GROUP BY 1,2,3,4,5,6,7,8, 12, 17,19,20,21,22,23,24
;
]]>
date_debut_contrat
;
UPDATE rh.p_salaries
SET date_entree_ets = date_debut_contrat
FROM (SELECT salarie_id, min(date_debut) AS date_debut_contrat from rh.p_contrats group by 1) AS s
WHERE 1=1
AND p_salaries.oid = s.salarie_id
AND to_char(date_entree_ets, 'YYYY')::numeric >= 2009
AND date_entree_ets < date_debut_contrat
;
UPDATE rh.p_salaries
SET date_sortie_ets = date_fin_contrat
FROM (SELECT salarie_id, max(date_fin) AS date_fin_contrat from rh.p_contrats group by 1) AS s
WHERE 1=1
AND p_salaries.oid = s.salarie_id
AND date_fin_contrat > date_sortie_ets
;
-- Calcul ancienneté au début de contrat
UPDATE rh.p_contrats
SET
anciennete_anterieure_jours = subq.anciennete_anterieure_jours,
anciennete_anterieure_calculee_mois = subq.anciennete_anterieure_calculee_mois
FROM (
SELECT
t1.numero_contrat,
sum(t2.duree) AS anciennete_anterieure_jours,
sum(t2.duree) / 30 AS anciennete_anterieure_calculee_mois
FROM w_cnt AS t1
JOIN w_cnt AS t2 ON 1=1
AND t2.sal_matr = t1.sal_matr
AND t2.date_debut < t1.date_debut
group by 1
) AS subq
WHERE 1=1
AND p_contrats.numero_contrat = subq.numero_contrat
;
TRUNCATE rh.p_contrats_mois
;
ALTER SEQUENCE rh.s_contrats_mois RESTART WITH 1
;
INSERT INTO rh.p_contrats_mois(
code_original,
salarie_id,
contrat_id,
mois_activite,
date_debut,
date_fin,
nombre_entrees,
nombre_departs,
nombre_debut_contrat,
nombre_fin_contrat,
est_hors_periode,
present_debut_mois,
present_fin_mois,
equivalent_temps_plein,
nombre_heures,
age_id,
age_jours,
anciennete_jours,
anciennete_mois,
anciennete_annee_id)
SELECT
w_profils.code_original,
p_salaries.oid AS salarie_id,
p_contrats.oid AS contrat_id,
p_calendrier_mois.mois AS mois,
GREATEST(p_calendrier_mois.date_debut, w_profils.date_debut) AS date_debut,
LEAST(p_calendrier_mois.date_fin, w_profils.date_fin) AS date_fin,
CASE WHEN p_salaries.date_entree_ets BETWEEN p_calendrier_mois.date_debut AND p_calendrier_mois.date_fin THEN 1 ELSE 0 END AS nombre_entrees,
CASE WHEN p_salaries.date_sortie_ets BETWEEN p_calendrier_mois.date_debut AND p_calendrier_mois.date_fin THEN 1 ELSE 0 END AS nombre_departs,
CASE WHEN p_contrats.date_debut BETWEEN p_calendrier_mois.date_debut AND p_calendrier_mois.date_fin THEN 1 ELSE 0 END AS nombre_debut_contrat,
CASE WHEN p_contrats.date_fin BETWEEN p_calendrier_mois.date_debut AND p_calendrier_mois.date_fin THEN 1 ELSE 0 END AS nombre_fin_contrat,
w_profils.est_hors_periode,
CASE WHEN p_calendrier_mois.date_debut BETWEEN p_contrats.date_debut AND p_contrats.date_fin THEN 1 ELSE 0 END AS present_debut_mois,
CASE WHEN p_calendrier_mois.date_fin BETWEEN p_contrats.date_debut AND p_contrats.date_fin THEN 1 ELSE 0 END AS present_fin_mois,
etp_contrat,
heures_contrat,
base.cti_age(LEAST(p_calendrier_mois.date_fin, w_profils.date_fin), COALESCE(p_salaries.date_naissance, '1962-04-18'::date), 'ny') AS age_id,
LEAST(p_calendrier_mois.date_fin, w_profils.date_fin)::date - COALESCE(p_salaries.date_naissance, '1962-04-18'::date) AS age_jours,
p_contrats.anciennete_anterieure_jours
+ (LEAST(p_calendrier_mois.date_fin, w_profils.date_fin) - p_contrats.date_debut)
+ 1
AS anciennete_jours,
base.cti_months_between(p_contrats.date_debut, p_calendrier_mois.date_fin)
+ p_contrats.anciennete_anterieure_calculee_mois
AS anciennete_mois,
floor(
(
base.cti_months_between(p_contrats.date_debut, p_calendrier_mois.date_fin)
+ p_contrats.anciennete_anterieure_calculee_mois
) / 12
) AS anciennete_annee_id
FROM w_profils
JOIN base.p_calendrier_mois ON base.cti_overlaps(w_profils.date_debut, w_profils.date_fin, p_calendrier_mois.date_debut, p_calendrier_mois.date_fin)
JOIN rh.p_contrats ON p_contrats.numero_contrat = w_profils.numero_contrat
JOIN rh.p_salaries ON p_salaries.matricule = w_profils.matricule
WHERE 1=1
AND p_calendrier_mois.mois < to_char(now() + '1 month'::interval, 'YYYYMM')
GROUP BY 1,2,3,4,5,6,7,8,9,10,11,12,13,14,15,16,17,18,19
;
]]>
heures).
-- En revanche, les autres salariés voient leur base multiplié par le coeff paramétré dans nombre (représente toujours des jours).
-- Cela permet d'appliquer le signe négatif sur la base de toute la population de salariés.
case when p_base then lig_bas1 else 0 end * case when forfait_jour then c_base * bulletin.etp else c_nombre end AS base,
case when p_nombre then lig_bas2 else 0 end * c_nombre AS nombre,
case
when p_heures_contrat and s_heures_contrat = 0 then lig_bas2
when p_heures_contrat and s_heures_contrat = 1 then lig_bas1
else 0
end * c_heures_contrat as heure_contrat,
case
when p_heures_payees and s_heures_payees = 0 then lig_bas2
when p_heures_payees and s_heures_payees = 1 then lig_bas1
else 0
end * c_heures_payees as heure_payee,
case
when p_heures_travaillees and s_heures_travaillees = 0 then lig_bas2
when p_heures_travaillees and s_heures_travaillees = 1 then lig_bas1
else 0
end * c_heures_travaillees as heure_travaillee,
case
when p_masse_salariale and s_masse_salariale = 3 then lig_mont1
when p_masse_salariale and s_masse_salariale = 5 then lig_mont2
else 0
end * c_masse_salariale as montant_masse_salariale,
CASE WHEN p_brut THEN lig_mont1 ELSE 0 END * c_brut AS montant_brut,
CASE WHEN p_avantage_nature THEN lig_mont1 ELSE 0 END * c_avantage_nature AS montant_avantage_nature,
case when p_frais_imposables then lig_mont1 else 0 end * c_frais_imposables as montant_frais_imposables,
case when p_cotisation_salarie then lig_mont1 else 0 end * c_cotisation_salarie as montant_cotisation_salarie,
case when p_cotisation_patronale then lig_mont2 else 0 end * c_cotisation_patronale as montant_cotisation_patronale,
case when p_od_net_salarie then lig_mont1 else 0 end * c_od_net_salarie as montant_od_net_salarie,
case when p_od_net_patronale then lig_taux2 else 0 end * c_od_net_patronale as montant_od_net_patronale,
lig_taux1 AS tx_sal,
lig_taux2 AS tx_pat,
CASE WHEN p_net_imposable THEN lig_mont1 ELSE 0 END * c_net_imposable AS montant_net_imposable_salarie,
CASE WHEN p_net_a_payer THEN lig_mont1 ELSE 0 END * c_net_a_payer AS montant_net_a_payer_salarie
FROM w_bulletin AS bulletin
JOIN w_ets ON w_ets.eta_id = bulletin.eta_id
join ligne ON 1=1
AND ligne.bul_id = bulletin.bul_id
AND ligne.ent_id = bulletin.ent_id
join w_rub ON 1=1
AND w_rub.pla_id = ligne.pla_id
AND bulletin.bul_fin between w_rub.pla_dval and w_rub.pla_fval
join rh.t_rubriques on t_rubriques.code_original = w_rub.pla_code_original
WHERE 1!=1
OR p_detail
OR p_cumul
;
-- #correction
UPDATE w_hp
SET date_paie = (mois_paie||'01')::date + '1 month - 1 day'::interval
WHERE to_char(date_paie, 'YYYYMM')::numeric != mois_paie
;
CREATE INDEX i_w_hp_1
ON w_hp
USING btree (matricule)
;
CREATE INDEX i_w_hp_2
ON w_hp
USING btree (mois_activite)
;
CREATE INDEX i_w_hp_3
ON w_hp
USING btree (mois_paie)
;
CREATE INDEX i_w_hp_4
ON w_hp
USING btree (rubrique)
;
-- Insertion dans la table de production CTI.
TRUNCATE rh.p_historique_paie
;
SELECT base.cti_stash_table_indexes('rh', 'p_historique_paie')
;
INSERT INTO rh.p_historique_paie(
age_id,
nombre,
base,
contrat_id,
contrat_mois_id,
date_debut,
date_fin,
date_paie,
mois_activite,
mois_paie,
heure_contrat,
heure_payee,
heure_travaillee,
montant_avantage_nature,
montant_brut,
montant_masse_salariale,
montant_cotisation_patronale,
montant_cotisation_salarie,
montant_frais_imposables,
montant_net_a_payer_salarie,
montant_net_imposable_salarie,
montant_od_net_salarie,
montant_od_net_patronale,
organisme_cotisation_id,
rubrique_id,
salarie_id,
taux_cotisation_patronale,
taux_cotisation_salarie,
compte_id)
SELECT
date_part('year', age(w_hp.date_debut, date_naissance)) AS age_id,
w_hp.nombre,
w_hp.base AS base,
(max(ARRAY[EXTRACT(EPOCH FROM p_contrats_mois.date_fin),p_contrats_mois.contrat_id]))[2] AS contrat_id,
(max(ARRAY[EXTRACT(EPOCH FROM p_contrats_mois.date_fin),p_contrats_mois.oid]))[2] AS contrat_mois_id,
w_hp.date_debut,
w_hp.date_fin,
w_hp.date_paie,
w_hp.mois_activite,
w_hp.mois_paie,
w_hp.heure_contrat,
w_hp.heure_payee,
w_hp.heure_travaillee,
w_hp.montant_avantage_nature,
w_hp.montant_brut,
w_hp.montant_masse_salariale,
w_hp.montant_cotisation_patronale,
w_hp.montant_cotisation_salarie,
w_hp.montant_frais_imposables,
w_hp.montant_net_a_payer_salarie,
w_hp.montant_net_imposable_salarie,
w_hp.montant_od_net_salarie,
w_hp.montant_od_net_patronale,
0 AS organisme_cotisation_id,
t_rubriques.oid AS rubrique_id,
p_salaries.oid AS salarie_id,
w_hp.tx_pat AS taux_cotisation_patronale,
w_hp.tx_sal AS taux_cotisation_salarie,
0 AS compte_id
FROM w_hp
JOIN rh.t_rubriques ON t_rubriques.code_original = w_hp.rubrique
JOIN rh.p_salaries ON p_salaries.matricule = w_hp.matricule
-- LEFT JOIN rh.t_organismes_cotisation ON t_organismes_cotisation.code_original = w_hp.organisme
LEFT JOIN rh.p_contrats_mois ON 1=1
AND p_contrats_mois.salarie_id = p_salaries.oid
--AND p_contrats_mois.mois_activite = w_hp.mois
AND base.cti_overlaps(p_contrats_mois.date_debut, p_contrats_mois.date_fin, w_hp.date_debut, w_hp.date_fin)
-- LEFT JOIN rh.t_compte ON t_compte.code_original = w_hp.compte
WHERE w_hp.p_detail
GROUP BY 1,2,3, 6,7,8,9,10,11,12,13,14,15,16,17,18,19,20,21,22,23,24,25,26,27,28,29, w_hp.ctid
;
SELECT base.cti_stash_pop_table_indexes('rh', 'p_historique_paie')
;
-- Création d'une table temp qui regroupe tous les totaux à atteindre pour calculer l'écart
DROP TABLE IF EXISTS w_totaux
;
-- FIXME ATTENTION AUX DOUBLONS !!!
-- FIXME Bulletins sur 201600 ...
CREATE TEMP TABLE w_totaux AS
with ligne as (
select
bul_id,
ligne.ent_id,
pla_id,
lig_bas1,
lig_bas2,
lig_mont1,
lig_mont2
from w_ligne as ligne
JOIN w_ets ON w_ets.ent_id = ligne.ent_id
union all
select
bul_id,
ent_id,
code as pla_id,
base as lig_bas1,
nombre as lig_bas2,
0 as lig_mont1,
0 as lig_mont2
from w_ligne_fj)
select
-- Dates d'activité
date_debut,
date_fin,
to_char(date_fin, 'YYYYMM')::numeric AS mois_activite,
-- Dates de paie
date_paie,
substr(bulletin.bul_id, 1, 6)::numeric AS mois_paie,
bulletin.eta_id,
bulletin.sal_matr AS matricule,
substr(bulletin.bul_id, 1, 4)::numeric AS mois,
sum(case when pla_id = 'BRUT' then lig_mont1 else 0 end)::numeric AS brut,
sum(case when pla_id = 'IMPO' then lig_mont1 else 0 end)::numeric AS net_imposable,
sum(case when pla_id = 'NETT' then lig_mont1 else 0 end)::numeric AS net_a_payer,
sum(case when pla_id = 'TOTR' then lig_mont1 else 0 end)::numeric AS mt_sal,
sum(case when pla_id = 'TOTR' then lig_mont2 * (-1) else 0 end)::numeric AS mt_pat
from w_bulletin AS bulletin
JOIN w_ets ON w_ets.eta_id = bulletin.eta_id
join ligne ON 1=1
AND ligne.bul_id = bulletin.bul_id
AND ligne.ent_id = bulletin.ent_id
where pla_id IN ('BRUT', 'TOTR', 'IMPO', 'NETT')
group by 1,2,3,4,5,6,7,8
;
-- #correction
UPDATE w_totaux
SET date_paie = (mois_paie||'01')::date + '1 month - 1 day'::interval
WHERE to_char(date_paie, 'YYYYMM')::numeric != mois_paie
;
-- Inserer pour chaque bulletin une ligne qui va faire le compte avec le total (rubrique 'C000' nommée 'Ecart cumulé')
INSERT INTO rh.p_historique_paie(
age_id,
contrat_id,
contrat_mois_id,
date_debut,
date_fin,
date_paie,
mois_activite,
mois_paie,
nombre,
base,
heure_payee,
heure_travaillee,
montant_masse_salariale,
montant_brut,
montant_avantage_nature,
montant_frais_imposables,
montant_cotisation_salarie,
montant_cotisation_patronale,
montant_od_net_salarie,
montant_od_net_patronale,
montant_net_imposable_salarie,
montant_net_a_payer_salarie,
organisme_cotisation_id,
profil_id, -- @deprecated
rubrique_id,
salarie_id,
taux_cotisation_patronale,
taux_cotisation_salarie)
SELECT
age_id,
contrat_id,
contrat_mois_id,
subq.date_debut,
subq.date_fin,
subq.date_paie,
subq.mois_activite,
subq.mois_paie,
0 as nombre,
0 AS base,
0 AS heure_payee,
0 as heure_travaillee,
0 as montant_masse_salariale,
sum(brut - subq.montant_brut) AS montant_brut,
0 AS montant_avantage_nature,
0 AS montant_frais_imposables,
sum(mt_sal - subq.montant_cotisation_salarie) AS montant_cotisation_salarie,
sum(mt_pat - subq.montant_cotisation_patronale) AS montant_cotisation_patronale,
0 as montant_od_net_salarie,
0 as montant_od_net_patronale,
sum(net_imposable - subq.montant_net_imposable_salarie) AS montant_net_imposable_salarie,
sum(net_a_payer - subq.montant_net_a_payer_salarie) AS montant_net_a_payer_salarie,
subq.organisme_cotisation_id AS organisme_cotisation_id,
subq.profil_id AS profil_id,
(SELECT oid FROM rh.t_rubriques WHERE code = 'C000') AS rubrique_id,
subq.salarie_id AS salarie_id,
0 AS taux_cotisation_patronale,
0 AS taux_cotisation_salarie
FROM
(SELECT
p_historique_paie.age_id,
p_historique_paie.contrat_id,
p_historique_paie.contrat_mois_id,
p_historique_paie.date_debut,
p_historique_paie.date_fin,
p_historique_paie.date_paie,
p_historique_paie.mois_activite,
p_historique_paie.mois_paie,
0 as nombre,
0 AS base,
sum(heure_payee) as heure_payee,
sum(heure_travaillee) as heure_travaillee,
sum(montant_masse_salariale) as montant_masse_salariale,
sum(montant_brut) AS montant_brut,
sum(montant_avantage_nature) AS montant_avantage_nature,
sum(montant_frais_imposables) AS montant_frais_imposables,
sum(montant_cotisation_salarie) AS montant_cotisation_salarie,
sum(montant_cotisation_patronale) AS montant_cotisation_patronale,
sum(montant_od_net_salarie) as montant_od_net_salarie,
sum(montant_od_net_patronale) as montant_od_net_patronale,
sum(montant_net_imposable_salarie) AS montant_net_imposable_salarie,
sum(montant_net_a_payer_salarie) AS montant_net_a_payer_salarie,
0 AS organisme_cotisation_id,
0 AS profil_id, -- p_historique_paie.profil_id,
(SELECT oid FROM rh.t_rubriques WHERE code = 'C000'),
p_historique_paie.salarie_id,
0 AS taux_cotisation_patronale,
0 AS taux_cotisation_salarie
FROM rh.p_historique_paie
JOIN rh.p_salaries ON p_salaries.oid = p_historique_paie.salarie_id
GROUP BY 1,2,3,4,5,6,7,8,9,10, 23,24,25,26,27,28) AS subq
JOIN rh.p_salaries ON p_salaries.oid = subq.salarie_id
JOIN w_totaux ON 1=1
AND w_totaux.matricule = p_salaries.matricule
AND w_totaux.date_debut = subq.date_debut
AND w_totaux.date_fin = subq.date_fin
GROUP BY 1,2,3,4,5,6,7,8, 23,24,25,26,27,28
HAVING 1!=1
OR sum(brut - subq.montant_brut) != 0
OR sum(mt_pat - subq.montant_cotisation_patronale) != 0
OR sum(mt_sal - subq.montant_cotisation_salarie) != 0
OR sum(net_a_payer - subq.montant_net_a_payer_salarie) != 0
OR sum(net_imposable - subq.montant_net_imposable_salarie) != 0
;
/*
Quels sont les écarts cumulés > 0 ? :
SELECT
p_salaries.matricule,
p_historique_paie.*
FROM rh.p_historique_paie
JOIN rh.p_salaries on p_salaries.oid = p_historique_paie.salarie_id
JOIN rh.t_rubriques on t_rubriques.oid = p_historique_paie.rubrique_id
WHERE 1=1
AND t_rubriques.code_original = 'C000'
AND
(1!=1
OR p_historique_paie.base <> 0
OR p_historique_paie.montant_brut <> 0
OR p_historique_paie.montant_cotisation_salarie <> 0
OR p_historique_paie.montant_cotisation_patronale <> 0
OR p_historique_paie.montant_net_a_payer_salarie <> 0
OR p_historique_paie.montant_net_imposable_salarie <> 0
OR p_historique_paie.montant_avantage_nature <> 0
)
ORDER BY 1,4 DESC
;
*/
]]>