<?xml version="1.0" encoding="ISO-8859-15"?>
|
|
<ROOT>
|
|
<NODE name="INIT" label="INITIALISATIONS">
|
|
<NODE label="Ajustement des formats">
|
|
<sqlcmd><![CDATA[
|
|
|
|
UPDATE prod_quadrarh.entreesortieemp
|
|
SET DATEES = substr(DATEES,7,4) || '-' || substr(DATEES,4,2) || '-' || substr(DATEES,1,2) || substr(DATEES,11)
|
|
WHERE substr(DATEES,3,1) = '/' AND substr(DATEES,6,1) = '/'
|
|
;
|
|
|
|
UPDATE prod_quadrarh.entreesortieemp
|
|
SET DATEMODIFICATION = substr(DATEMODIFICATION,7,4) || '-' || substr(DATEMODIFICATION,4,2) || '-' || substr(DATEMODIFICATION,1,2) || substr(DATEMODIFICATION,11)
|
|
WHERE substr(DATEMODIFICATION,3,1) = '/' AND substr(DATEMODIFICATION,6,1) = '/'
|
|
;
|
|
|
|
UPDATE prod_quadrarh.entreesortieemp
|
|
SET DATENOTIFICATION = substr(DATENOTIFICATION,7,4) || '-' || substr(DATENOTIFICATION,4,2) || '-' || substr(DATENOTIFICATION,1,2) || substr(DATENOTIFICATION,11)
|
|
WHERE substr(DATENOTIFICATION,3,1) = '/' AND substr(DATENOTIFICATION,6,1) = '/'
|
|
;
|
|
|
|
UPDATE prod_quadrarh.employes
|
|
SET DATENAISSANCE = substr(DATENAISSANCE,7,4) || '-' || substr(DATENAISSANCE,4,2) || '-' || substr(DATENAISSANCE,1,2) || substr(DATENAISSANCE,11)
|
|
WHERE substr(DATENAISSANCE,3,1) = '/' AND substr(DATENAISSANCE,6,1) = '/'
|
|
;
|
|
|
|
UPDATE prod_quadrarh.bulletins
|
|
SET PERIODE = substr(PERIODE,7,4) || '-' || substr(PERIODE,4,2) || '-' || substr(PERIODE,1,2) || substr(PERIODE,11)
|
|
WHERE substr(PERIODE,3,1) = '/' AND substr(PERIODE,6,1) = '/'
|
|
;
|
|
|
|
UPDATE prod_quadrarh.infoscomplbul
|
|
SET PERIODE = substr(PERIODE,7,4) || '-' || substr(PERIODE,4,2) || '-' || substr(PERIODE,1,2) || substr(PERIODE,11)
|
|
WHERE substr(PERIODE,3,1) = '/' AND substr(PERIODE,6,1) = '/'
|
|
;
|
|
|
|
UPDATE prod_quadrarh.lignesbulletin
|
|
SET PERIODE = substr(PERIODE,7,4) || '-' || substr(PERIODE,4,2) || '-' || substr(PERIODE,1,2) || substr(PERIODE,11)
|
|
WHERE substr(PERIODE,3,1) = '/' AND substr(PERIODE,6,1) = '/'
|
|
;
|
|
|
|
UPDATE prod_quadrarh.bulletins SET
|
|
NBHNORMAL = replace(NBHNORMAL,',','.'),
|
|
NBHTRAV = replace(NBHTRAV,',','.'),
|
|
BRUT = replace(BRUT,',','.'),
|
|
TOTRETENUE = replace(TOTRETENUE,',','.'),
|
|
TOTCOTISPATRON = replace(TOTCOTISPATRON,',','.'),
|
|
NETIMPOS = replace(NETIMPOS,',','.'),
|
|
NETAPAYER = replace(NETAPAYER,',','.')
|
|
;
|
|
|
|
UPDATE prod_quadrarh.infoscomplbul SET
|
|
NBHEUREMOIS = replace(NBHEUREMOIS,',','.')
|
|
;
|
|
|
|
UPDATE prod_quadrarh.lignesbulletin SET
|
|
MONTANT1 = replace(MONTANT1,',','.'),
|
|
MONTANT2 = replace(MONTANT2,',','.'),
|
|
MONTANTSALARIAL = replace(MONTANTSALARIAL,',','.'),
|
|
MONTANTGLOBAL = replace(MONTANTGLOBAL,',','.')
|
|
;
|
|
|
|
UPDATE rh.p_salaries
|
|
SET code_original = trim(code_original)
|
|
WHERE code_original <> trim(code_original)
|
|
;
|
|
|
|
UPDATE prod_quadrarh.employes
|
|
SET NUMERO = trim(NUMERO)
|
|
WHERE NUMERO <> trim(NUMERO)
|
|
;
|
|
|
|
UPDATE prod_quadrarh.bulletins
|
|
SET NUMEROEMPLOYE = trim(NUMEROEMPLOYE)
|
|
WHERE NUMEROEMPLOYE <> trim(NUMEROEMPLOYE)
|
|
;
|
|
|
|
UPDATE prod_quadrarh.entreesortieemp
|
|
SET NUMEROEMPLOYE = trim(NUMEROEMPLOYE)
|
|
WHERE NUMEROEMPLOYE <> trim(NUMEROEMPLOYE)
|
|
;
|
|
|
|
UPDATE prod_quadrarh.infoscomplbul
|
|
SET NUMERO = trim(NUMERO)
|
|
WHERE NUMERO <> trim(NUMERO)
|
|
;
|
|
|
|
UPDATE prod_quadrarh.lignesbulletin
|
|
SET NUMEROEMPLOYE = trim(NUMEROEMPLOYE)
|
|
WHERE NUMEROEMPLOYE <> trim(NUMEROEMPLOYE)
|
|
;
|
|
|
|
UPDATE prod_quadrarh.infoscomplbul
|
|
SET CDDCDI = CASE WHEN CDDCDI ILIKE 'True' THEN '1' WHEN CDDCDI ILIKE 'False' THEN '0' ELSE CDDCDI END
|
|
WHERE CDDCDI ILIKE 'True' OR CDDCDI ILIKE 'False'
|
|
;
|
|
|
|
]]></sqlcmd>
|
|
</NODE>
|
|
|
|
<NODE label="Pré-traitements">
|
|
<sqlcmd><![CDATA[
|
|
|
|
DROP TABLE IF EXISTS w_cnt_mois
|
|
;
|
|
|
|
CREATE TEMP TABLE w_cnt_mois AS
|
|
with raw_data as (
|
|
select
|
|
numeroemploye,
|
|
case when typees = 1 then datees::date else null end as date_debut,
|
|
case when lead(typees) over w = 2 then lead(datees::date) over w else '2099-12-31'::date end as date_fin,
|
|
typees,
|
|
coalesce(case when lead(typees) over w = 2 then lead(codemotifrupture) over w else null end, codemotifrupture) as codemotifrupture
|
|
from prod_quadrarh.entreesortieemp
|
|
window w as (partition by numeroemploye order by datees::date, typees)
|
|
union all
|
|
-- Correction spécifique Les Fleurs icti_430 : bug "exceptionnel" du logiciel Quadra RH.
|
|
select
|
|
'7685'::text,
|
|
'2018-03-24'::date,
|
|
'2018-03-24'::date,
|
|
'1'::text,
|
|
'31'::text
|
|
where current_database() = 'icti_430'
|
|
)
|
|
, filtered_data as (
|
|
select
|
|
numeroemploye,
|
|
date_debut,
|
|
date_fin,
|
|
codemotifrupture
|
|
from raw_data
|
|
where typees = 1)
|
|
, w_cnt as (
|
|
select
|
|
row_number() over () as cti_cnt,
|
|
numeroemploye||'-'||rank() over w as ncnt,
|
|
-- row_number() over w2 - 1 as sequence, -- Attention cette séquence peut-être fause lorsqu'un contrat courant sur plusieurs mois débute sur un mois avec plusieurs contrats infra-mois.
|
|
numeroemploye,
|
|
date_debut,
|
|
-- to_char(date_debut, 'YYYYMM')::int as mois_debut,
|
|
date_fin,
|
|
-- to_char(date_fin, 'YYYYMM')::int as mois_fin,
|
|
codemotifrupture
|
|
from filtered_data
|
|
window w as (partition by numeroemploye order by date_debut))
|
|
select
|
|
w_cnt.cti_cnt,
|
|
w_cnt.ncnt,
|
|
numeroemploye,
|
|
case when count(*) over w1 = 1 then 0 else row_number() over w2 - 1 end as sequence,
|
|
w_cnt.date_debut as cnt_date_debut,
|
|
w_cnt.date_fin as cnt_date_fin,
|
|
greatest(cal.date_debut, w_cnt.date_debut) as date_debut,
|
|
least(cal.date_fin, w_cnt.date_fin) as date_fin,
|
|
cal.mois,
|
|
codemotifrupture
|
|
from w_cnt
|
|
join base.p_calendrier_mois as cal on base.cti_overlaps(cal.date_debut, cal.date_fin, w_cnt.date_debut, w_cnt.date_fin)
|
|
where 1=1
|
|
and cal.mois <= to_char(CURRENT_DATE + '1 month'::interval, 'YYYYMM')
|
|
-- and numeroemploye = 3730
|
|
window w1 as (partition by numeroemploye order by cal.mois),
|
|
w2 as (partition by numeroemploye, cal.mois order by w_cnt.date_debut)
|
|
;
|
|
-- CREATE OR REPLACE VIEW prod_quadrarh.bulletins AS
|
|
-- with b0 as (select row_number() over () as r0, * from prod_quadrarh.bulletins_0),
|
|
-- b1 as (select row_number() over () as r1, * from prod_quadrarh.bulletins_1),
|
|
-- b2 as (select row_number() over () as r2, * from prod_quadrarh.bulletins_2),
|
|
-- b3 as (select row_number() over () as r3, * from prod_quadrarh.bulletins_3),
|
|
-- b4 as (select row_number() over () as r4, * from prod_quadrarh.bulletins_4)
|
|
-- select *
|
|
-- from b0
|
|
-- join b1 on b1.r1 = b0.r0
|
|
-- join b2 on b2.r2 = b0.r0
|
|
-- join b3 on b3.r3 = b0.r0
|
|
-- join b4 on b4.r4 = b0.r0
|
|
-- ;
|
|
|
|
DROP TABLE IF EXISTS w_bul
|
|
;
|
|
|
|
CREATE TEMP TABLE w_bul AS
|
|
select
|
|
row_number() over () as cti_bul,
|
|
codeetablissement,
|
|
numeroemploye,
|
|
periode::date as date_paie,
|
|
to_char(periode::date, 'YYYYMM')::int as mois_paie,
|
|
indiceperiode as sequence,
|
|
-- dtdebutperiode::date as date_debut,
|
|
-- dtfinperiode::date as date_fin,
|
|
nbhnormal::numeric as h_contrat,
|
|
nbhtrav::numeric as h_payees,
|
|
brut::numeric as brut,
|
|
totretenue::numeric as cot_sal,
|
|
totcotispatron::numeric as cot_pat,
|
|
netimpos::numeric as net_imposable,
|
|
netapayer::numeric as net_a_payer
|
|
from prod_quadrarh.bulletins
|
|
;
|
|
|
|
-- CREATE OR REPLACE VIEW prod_quadrarh.employes AS
|
|
-- with b0 as (select row_number() over () as r0, * from prod_quadrarh.employes_0),
|
|
-- b1 as (select row_number() over () as r1, * from prod_quadrarh.employes_1),
|
|
-- b2 as (select row_number() over () as r2, * from prod_quadrarh.employes_2)
|
|
-- select *
|
|
-- from b0
|
|
-- join b1 on b1.r1 = b0.r0
|
|
-- join b2 on b2.r2 = b0.r0
|
|
-- ;
|
|
|
|
-- Parametrage des champs sources
|
|
INSERT INTO rh.t_divers(code, description, texte, valeur)
|
|
SELECT code, texte, texte, ''
|
|
FROM
|
|
(
|
|
SELECT 'QUADRA_QUALIF_COLUMN'::text AS code, 'Colonne source pour qualification'::text AS texte
|
|
UNION
|
|
SELECT 'QUADRA_STATUT_COLUMN'::text AS code, 'Colonne source pour statut'::text AS texte
|
|
) subview
|
|
WHERE code NOT IN (SELECt code FROM rh.t_divers)
|
|
;
|
|
|
|
DROP TABLE IF EXISTS w_hst
|
|
;
|
|
CREATE TEMP TABLE w_hst AS
|
|
with toto as (
|
|
select
|
|
row_number() over () as cti_hst,
|
|
numero as numeroemploye,
|
|
periode::date as date_paie,
|
|
to_char(periode::date, 'YYYYMM')::int as mois_paie,
|
|
indiceperiode as sequence,
|
|
case when rank() over w = 1 then '0001-01-01'::date else periode::date end as date_debut,
|
|
coalesce(lead(periode::date) over w - '1 day'::interval, '2099-12-31'::date)::date as date_fin,
|
|
EMPLOI AS EMPLOI_source,
|
|
QUALIFICATION AS QUALIFICATION_source,
|
|
substr(md5(emploi), 1, 5) as emploi_code,
|
|
emploi as emploi_libelle,
|
|
substr(md5(qualification), 1, 5) as qualification_code,
|
|
qualification as qualification_libelle,
|
|
service,
|
|
tds59,
|
|
nbheuremois::numeric,
|
|
case when nbheuremois::numeric in (151.67, 0.0) then 1.0 else nbheuremois::numeric / 151.67 end as ratio_theo,
|
|
case when nbheuremois::numeric in (151.67, 0.0) then 'TC'||to_char(nbheuremois::numeric, 'FM000.00') else 'TP'||to_char(nbheuremois::numeric, 'FM000.00') end as ttt,
|
|
case when nbheuremois::numeric in (151.67, 0.0) then 'Temps Complet' else 'Temps Partiel '||replace(round((nbheuremois::numeric/151.67*100.0), 2), '.', ',')|| ' %' end as ttt_libelle,
|
|
case when nbheuremois::numeric in (151.67, 0.0) then 'TC' else 'TP '||replace(round((nbheuremois::numeric/151.67*100.0), 2), '.', ',')|| ' %' end as ttt_libelle_court,
|
|
case when cddcdi = 1 then 'CDD' else 'CDI' end as cddcdi,
|
|
typecontrat,
|
|
categsalarie,
|
|
codestatutpro,
|
|
codestatutcateg,
|
|
classification,
|
|
niveau,
|
|
position,
|
|
categpopulation,
|
|
classification AS statut_code,
|
|
classification AS statut_libelle
|
|
from prod_quadrarh.infoscomplbul
|
|
window w as (partition by numero order by periode::date, indiceperiode))
|
|
select
|
|
cti_hst,
|
|
numeroemploye,
|
|
case when mois_paie = cal.mois then date_paie else null end as date_paie,
|
|
case when mois_paie = cal.mois then mois_paie else null end as mois_paie,
|
|
sequence,
|
|
cal.date_debut,
|
|
cal.date_fin,
|
|
EMPLOI_source,
|
|
QUALIFICATION_source,
|
|
emploi_code,
|
|
emploi_libelle,
|
|
qualification_code,
|
|
qualification_libelle,
|
|
statut_code,
|
|
statut_libelle,
|
|
service,
|
|
tds59,
|
|
nbheuremois,
|
|
ratio_theo,
|
|
ttt,
|
|
ttt_libelle,
|
|
ttt_libelle_court,
|
|
cddcdi,
|
|
typecontrat,
|
|
categsalarie,
|
|
codestatutpro,
|
|
codestatutcateg,
|
|
classification,
|
|
niveau,
|
|
position,
|
|
categpopulation
|
|
from toto
|
|
join base.p_calendrier_mois as cal on cal.mois = toto.mois_paie
|
|
;
|
|
|
|
UPDATE w_HST SET
|
|
qualification_code = substr(md5(EMPLOI_source), 1, 5),
|
|
qualification_libelle = EMPLOI_source
|
|
FROM rh.t_divers
|
|
WHERE t_divers.code = 'QUADRA_QUALIF_COLUMN' AND
|
|
t_divers.valeur ILIKE 'emploi'
|
|
;
|
|
|
|
UPDATE w_HST SET
|
|
statut_code = substr(md5(QUALIFICATION_source), 1, 5),
|
|
statut_libelle = QUALIFICATION_source
|
|
FROM rh.t_divers
|
|
WHERE t_divers.code = 'QUADRA_STATUT_COLUMN' AND
|
|
t_divers.valeur ILIKE 'qualification'
|
|
;
|
|
|
|
]]></sqlcmd>
|
|
</NODE>
|
|
<NODE name="INIT" type="common" />
|
|
<NODE label="Mise à jour des informations permanentes">
|
|
<sqlcmd><![CDATA[
|
|
|
|
-- Màj des Entreprises.
|
|
INSERT INTO rh.t_entreprises(code_original, code, texte, texte_court)
|
|
select
|
|
substr(siret, 1, 9),
|
|
substr(siret, 1, 9),
|
|
(min(array[codeetablissement, raisonsociale]))[2],
|
|
substr((min(array[codeetablissement, raisonsociale]))[2], 1, 50)
|
|
from prod_quadrarh.etablissements
|
|
where 1=1
|
|
AND substr(siret, 1, 9) NOT IN (SELECT code_original FROM rh.t_entreprises WHERE code_original IS NOT NULL)
|
|
AND (1!=1
|
|
OR substr(siret, 1, 9) IN (SELECT rhp_in('siren')) -- Soit un ou plusieurs SIREN ont été défini,
|
|
OR siret IN (SELECT rhp_in('siren')) -- et/ou soit un ou plusieurs SIRET,
|
|
OR codeetablissement IN (SELECT rhp_in('siren'))) -- et/ou soit un ou plusieurs codes établissement.
|
|
GROUP BY 1,2
|
|
;
|
|
|
|
-- Màj des Etablissements.
|
|
INSERT INTO rh.t_etablissements(code_original, code, texte, texte_court, entreprise_id)
|
|
SELECT
|
|
siret,
|
|
siret,
|
|
max(raisonsociale),
|
|
max(substr(raisonsociale, 1, 50)),
|
|
t_entreprises.oid
|
|
FROM prod_quadrarh.etablissements
|
|
JOIN rh.t_entreprises ON t_entreprises.code_original = substr(etablissements.siret, 1, 9)
|
|
WHERE 1=1
|
|
AND siret NOT IN (SELECT code_original FROM rh.t_etablissements WHERE code_original IS NOT NULL)
|
|
AND (1!=1
|
|
OR substr(siret, 1, 9) IN (SELECT rhp_in('siren')) -- Soit un ou plusieurs SIREN ont été défini,
|
|
OR siret IN (SELECT rhp_in('siren')) -- et/ou soit un ou plusieurs SIRET,
|
|
OR codeetablissement IN (SELECT rhp_in('siren'))) -- et/ou soit un ou plusieurs codes établissement.
|
|
GROUP BY 1,2,5
|
|
;
|
|
|
|
-- Màj des catégories socio-professionnelles
|
|
INSERT INTO rh.t_categories_socio_professionnelle (code_original, code, texte, texte_court)
|
|
SELECT lower(tds59), lower(tds59), lower(tds59), substr(lower(tds59), 1, 50)
|
|
FROM w_hst
|
|
WHERE 1=1
|
|
AND lower(tds59) NOT IN (SELECT code_original FROM rh.t_categories_socio_professionnelle WHERE code_original IS NOT NULL)
|
|
GROUP BY 1,2,3,4
|
|
;
|
|
|
|
-- Màj des motifs de début de contrat.
|
|
-- INSERT INTO rh.t_motifs_debut_contrat(code_original, code, texte, texte_court)
|
|
-- SELECT code, code, substr(max(intitule),1,50), substr(max(intitule),1,50)
|
|
-- FROM prod_sage.t_motifsdecontrat
|
|
-- WHERE code NOT IN (SELECT code_original FROM rh.t_motifs_debut_contrat WHERE code_original IS NOT NULL)
|
|
-- GROUP BY 1,2
|
|
-- ORDER BY 2
|
|
-- ;
|
|
|
|
-- Màj des motifs de fin de contrat.
|
|
INSERT INTO rh.t_motifs_fin_contrat(code_original, code, texte, texte_court)
|
|
SELECT codemotifrupture, codemotifrupture, codemotifrupture, substr(codemotifrupture, 1, 50)
|
|
FROM w_cnt_mois
|
|
WHERE codemotifrupture NOT IN (SELECT code_original FROM rh.t_motifs_fin_contrat WHERE code_original IS NOT NULL)
|
|
GROUP BY 1,2,3,4
|
|
;
|
|
|
|
-- -- Màj des nationalités.
|
|
-- INSERT INTO rh.t_nationalites(code, texte, texte_court, code_original)
|
|
-- SELECT code, intitule, substr(intitule,1,50), code
|
|
-- FROM prod_sage.t_nationalite
|
|
-- WHERE code NOT IN (SELECT code_original FROM rh.t_nationalites WHERE code_original IS NOT NULL)
|
|
-- GROUP BY 1,2,3,4
|
|
-- ;
|
|
|
|
-- Màj des qualifications
|
|
INSERT INTO rh.t_qualifications(code_original, code, texte, texte_court)
|
|
SELECT qualification_code, qualification_code, MAX(qualification_libelle), MAX(substr(qualification_libelle, 1, 50))
|
|
FROM w_hst
|
|
WHERE qualification_code NOT IN (SELECT code_original FROM rh.t_qualifications WHERE code_original IS NOT NULL)
|
|
GROUP BY 1,2
|
|
;
|
|
|
|
-- Màj des rubriques
|
|
INSERT INTO rh.t_rubriques(code_original, code, texte, texte_court, rang_edition)
|
|
with all_rubs_0 as (
|
|
select
|
|
code,
|
|
code||'_0' as code_original,
|
|
max(intitule) as intitule
|
|
from prod_quadrarh.libelles
|
|
group by 1,2
|
|
union
|
|
select
|
|
code,
|
|
code||'_'||case when code = '.IJS' then (case when strpos(libelle, 'nette') > 0 then 'NET' else 'BRUT' end) else typeabsence end as code_original,
|
|
max(libelle) as intitule
|
|
from prod_quadrarh.lignesbulletin
|
|
group by 1,2)
|
|
, all_rubs as (
|
|
select
|
|
code,
|
|
code_original,
|
|
max(intitule) as intitule
|
|
from all_rubs_0
|
|
group by 1,2)
|
|
SELECT code_original, code, intitule, substr(intitule, 1, 50), -1
|
|
FROM all_rubs
|
|
WHERE code_original NOT IN (SELECT code_original FROM rh.t_rubriques WHERE code_original IS NOT NULL)
|
|
GROUP BY 1,2,3,4,5
|
|
;
|
|
|
|
-- -- Màj des situations de famille
|
|
-- INSERT INTO rh.t_situations_famille(code_original, code, texte, texte_court)
|
|
-- SELECT situationfamille, situationfamille, substr(situationfamille,1,50), situationfamille
|
|
-- FROM prod_sage.t_hst_famille
|
|
-- WHERE situationfamille NOT IN (SELECT code_original FROM rh.t_situations_famille WHERE code_original IS NOT NULL)
|
|
-- GROUP BY 1,2,3,4
|
|
-- ;
|
|
|
|
-- Màj des types de contrat
|
|
INSERT INTO rh.t_types_contrat(code_original, code, texte, texte_court)
|
|
SELECT cddcdi, cddcdi, cddcdi, substr(cddcdi, 1, 50)
|
|
FROM w_hst
|
|
WHERE cddcdi NOT IN (SELECT code_original FROM rh.t_types_contrat WHERE code_original IS NOT NULL)
|
|
GROUP BY 1,2,3,4
|
|
;
|
|
|
|
-- Màj des statuts
|
|
INSERT INTO rh.t_statuts(code_original, code, texte, texte_court)
|
|
select statut_code, statut_code, MAX(statut_libelle), MAX(substr(statut_libelle, 1, 50))
|
|
from w_hst
|
|
WHERE statut_code NOT IN (SELECT code_original FROM rh.t_statuts WHERE code_original IS NOT NULL)
|
|
GROUP BY 1,2
|
|
;
|
|
|
|
-- Màj des types de temps de travail
|
|
INSERT INTO rh.t_types_temps_travail(code_original, code, texte, texte_court)
|
|
select ttt, ttt, ttt_libelle, ttt_libelle_court
|
|
from w_hst
|
|
where ttt NOT IN (SELECT code_original FROM rh.t_types_temps_travail WHERE code_original IS NOT NULL)
|
|
group by 1,2,3,4
|
|
;
|
|
|
|
-- Màj des services
|
|
INSERT INTO rh.t_services(code_original, code, texte, texte_court)
|
|
SELECT code, code, intitule, substr(intitule, 1, 50)
|
|
FROM prod_quadrarh.services
|
|
WHERE code NOT IN (SELECT code_original FROM rh.t_services WHERE code_original IS NOT NULL)
|
|
GROUP BY 1,2,3,4
|
|
;
|
|
|
|
-- Màj des codes emploi. prod_quadrarh.profils ?
|
|
INSERT INTO rh.t_codes_emploi(code_original, code, texte, texte_court)
|
|
SELECT emploi_code, emploi_code, emploi_libelle, substr(emploi_libelle, 1, 50)
|
|
FROM w_hst
|
|
WHERE emploi_code NOT IN (SELECT code_original FROM rh.t_codes_emploi WHERE code_original IS NOT NULL)
|
|
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 classification, classification, classification, substr(classification, 1, 50)
|
|
from w_hst
|
|
WHERE classification NOT IN (SELECT code_original FROM rh.t_grilles_groupes WHERE code_original IS NOT NULL)
|
|
GROUP BY 1,2,3,4
|
|
;
|
|
|
|
]]></sqlcmd>
|
|
</NODE>
|
|
<NODE label="Paramétrage des rubriques">
|
|
<sqlcmd><![CDATA[
|
|
|
|
-- Pré-paramétrage automatique des rubriques (au mieux).
|
|
-- Cette requête n'intervient pas sur les rubriques paramétrées à la main.
|
|
-- s_* (source_) :
|
|
-- - 0 = nombre
|
|
-- - 1 = base
|
|
-- - 2 = taux salarial
|
|
-- - 3 = montant salarial
|
|
-- - 4 = taux patronal
|
|
-- - 5 = montant patronal
|
|
-- - 6 = montant salarial + montant patronal
|
|
update rh.t_rubriques set
|
|
p_detail = subq.p_detail,
|
|
p_nombre = subq.p_nombre,
|
|
s_nombre = 0,
|
|
c_nombre = 1,
|
|
p_base = subq.p_base,
|
|
s_base = 1,
|
|
c_base = 1,
|
|
p_heures_contrat = subq.p_heures_contrat,
|
|
s_heures_contrat = 0,
|
|
c_heures_contrat = 1,
|
|
p_heures_payees = subq.p_heures_payees,
|
|
s_heures_payees = 0,
|
|
c_heures_payees = 1,
|
|
p_heures_travaillees = subq.p_heures_travaillees,
|
|
s_heures_travaillees = 0,
|
|
c_heures_travaillees = 1,
|
|
p_masse_salariale = subq.p_masse_salariale,
|
|
s_masse_salariale = case when subq.p_cotisation_patronale or subq.p_od_net_patronale then 5 else 3 end,
|
|
c_masse_salariale = 1,
|
|
p_brut = subq.p_brut,
|
|
s_brut = 3,
|
|
c_brut = 1,
|
|
p_avantage_nature = subq.p_avantage_nature,
|
|
s_avantage_nature = 3,
|
|
c_avantage_nature = 1,
|
|
p_frais_imposables = subq.p_frais_imposables,
|
|
s_frais_imposables = 3,
|
|
c_frais_imposables = 1,
|
|
p_cotisation_salarie = subq.p_cotisation_salarie,
|
|
s_cotisation_salarie = 3,
|
|
c_cotisation_salarie = -1,
|
|
p_cotisation_patronale = subq.p_cotisation_patronale,
|
|
s_cotisation_patronale = 5,
|
|
c_cotisation_patronale = 1,
|
|
p_od_net_salarie = subq.p_od_net_salarie,
|
|
s_od_net_salarie = 3,
|
|
c_od_net_salarie = case when subq.p_cotisation_salarie then -1 else 1 end,
|
|
p_od_net_patronale = subq.p_od_net_patronale,
|
|
s_od_net_patronale = 5,
|
|
c_od_net_patronale = 1,
|
|
p_net_imposable = subq.p_net_imposable,
|
|
s_net_imposable = 3,
|
|
c_net_imposable = case when subq.p_cotisation_salarie then -1 else 1 end,
|
|
p_net_a_payer = subq.p_net_a_payer,
|
|
s_net_a_payer = 3,
|
|
c_net_a_payer = case when subq.p_cotisation_salarie then -1 else 1 end
|
|
from (
|
|
select
|
|
oid,
|
|
substr(code, 1, 1) in ('B', 'E', 'S') AS p_detail,
|
|
substr(code, 1, 1) in ('B', 'E', 'S') AS p_nombre,
|
|
substr(code, 1, 1) in ('B', 'E', 'S') AS p_base,
|
|
false AS p_heures_contrat,
|
|
false AS p_heures_payees,
|
|
false AS p_heures_travaillees,
|
|
substr(code, 1, 1) in ('B', 'E') AS p_masse_salariale,
|
|
substr(code, 1, 1) in ('B') AS p_brut,
|
|
false AS p_avantage_nature,
|
|
false AS p_frais_imposables,
|
|
substr(code, 1, 1) in ('E') AS p_cotisation_salarie,
|
|
substr(code, 1, 1) in ('E') AS p_cotisation_patronale,
|
|
substr(code, 1, 1) in ('S') AS p_od_net_salarie,
|
|
false AS p_od_net_patronale,
|
|
substr(code, 1, 1) in ('B', 'E') AS p_net_imposable,
|
|
substr(code, 1, 1) in ('B', 'E', 'S') AS p_net_a_payer
|
|
from rh.t_rubriques
|
|
) as subq
|
|
where 1=1
|
|
and t_rubriques.oid = subq.oid
|
|
and NOT t_rubriques.user_modified
|
|
;
|
|
|
|
|
|
-- Rubriques avec code identique, copier paramétrage de la référence
|
|
UPDATE rh.t_rubriques SET
|
|
c_avantage_nature = t_rubriques_base.c_avantage_nature ,
|
|
c_base = t_rubriques_base.c_base ,
|
|
c_brut = t_rubriques_base.c_brut ,
|
|
c_cotisation_patronale = t_rubriques_base.c_cotisation_patronale ,
|
|
c_cotisation_salarie = t_rubriques_base.c_cotisation_salarie ,
|
|
c_frais_imposables = t_rubriques_base.c_frais_imposables ,
|
|
c_heures_contrat = t_rubriques_base.c_heures_contrat ,
|
|
c_heures_payees = t_rubriques_base.c_heures_payees ,
|
|
c_heures_travaillees = t_rubriques_base.c_heures_travaillees ,
|
|
c_masse_salariale = t_rubriques_base.c_masse_salariale ,
|
|
c_net_a_payer = t_rubriques_base.c_net_a_payer ,
|
|
c_net_imposable = t_rubriques_base.c_net_imposable ,
|
|
c_nombre = t_rubriques_base.c_nombre ,
|
|
c_od_net_patronale = t_rubriques_base.c_od_net_patronale ,
|
|
c_od_net_salarie = t_rubriques_base.c_od_net_salarie ,
|
|
p_avantage_nature = t_rubriques_base.p_avantage_nature ,
|
|
p_base = t_rubriques_base.p_base ,
|
|
p_brut = t_rubriques_base.p_brut ,
|
|
p_cotisation_patronale = t_rubriques_base.p_cotisation_patronale ,
|
|
p_cotisation_salarie = t_rubriques_base.p_cotisation_salarie ,
|
|
p_cumul = t_rubriques_base.p_cumul ,
|
|
p_detail = t_rubriques_base.p_detail ,
|
|
p_frais_imposables = t_rubriques_base.p_frais_imposables ,
|
|
p_heures_contrat = t_rubriques_base.p_heures_contrat ,
|
|
p_heures_payees = t_rubriques_base.p_heures_payees ,
|
|
p_heures_travaillees = t_rubriques_base.p_heures_travaillees ,
|
|
p_masse_salariale = t_rubriques_base.p_masse_salariale ,
|
|
p_net_a_payer = t_rubriques_base.p_net_a_payer ,
|
|
p_net_imposable = t_rubriques_base.p_net_imposable ,
|
|
p_nombre = t_rubriques_base.p_nombre ,
|
|
p_od_net_patronale = t_rubriques_base.p_od_net_patronale ,
|
|
p_od_net_salarie = t_rubriques_base.p_od_net_salarie ,
|
|
s_avantage_nature = t_rubriques_base.s_avantage_nature ,
|
|
s_base = t_rubriques_base.s_base ,
|
|
s_brut = t_rubriques_base.s_brut ,
|
|
s_cotisation_patronale = t_rubriques_base.s_cotisation_patronale ,
|
|
s_cotisation_salarie = t_rubriques_base.s_cotisation_salarie ,
|
|
s_frais_imposables = t_rubriques_base.s_frais_imposables ,
|
|
s_heures_contrat = t_rubriques_base.s_heures_contrat ,
|
|
s_heures_payees = t_rubriques_base.s_heures_payees ,
|
|
s_heures_travaillees = t_rubriques_base.s_heures_travaillees ,
|
|
s_masse_salariale = t_rubriques_base.s_masse_salariale ,
|
|
s_net_a_payer = t_rubriques_base.s_net_a_payer ,
|
|
s_net_imposable = t_rubriques_base.s_net_imposable ,
|
|
s_nombre = t_rubriques_base.s_nombre ,
|
|
s_od_net_patronale = t_rubriques_base.s_od_net_patronale ,
|
|
s_od_net_salarie = t_rubriques_base.s_od_net_salarie
|
|
FROM rh.t_rubriques t_rubriques_base
|
|
WHERE t_rubriques.code = t_rubriques_base.code AND
|
|
t_rubriques.user_modified = false AND
|
|
t_rubriques_base.user_modified = true AND
|
|
t_rubriques.code LIKE '.%'
|
|
;
|
|
]]></sqlcmd>
|
|
</NODE>
|
|
</NODE>
|
|
<NODE name="PROD" label="RECUPERATION DES DONNEES DE PRODUCTION">
|
|
<NODE label="Chiffrier">
|
|
<sqlcmd><![CDATA[
|
|
|
|
TRUNCATE rh.p_chiffrier_production
|
|
;
|
|
|
|
INSERT INTO rh.p_chiffrier_production (entreprise_id, etablissement_id, mois, nombre_salaries, montant_brut, nombre_heures)
|
|
SELECT
|
|
t_etablissements.entreprise_id,
|
|
t_etablissements.oid as etablissement_id,
|
|
w_bul.mois_paie,
|
|
count(DISTINCT numeroemploye),
|
|
sum(brut),
|
|
sum(h_payees)
|
|
FROM w_bul
|
|
JOIN prod_quadrarh.etablissements on etablissements.codeetablissement = w_bul.codeetablissement
|
|
JOIN rh.t_etablissements ON t_etablissements.code_original = etablissements.siret
|
|
WHERE w_bul.mois_paie >= to_char(rhp('rhprovider_start')::date, 'YYYYMM')::int
|
|
GROUP BY 1,2,3
|
|
;
|
|
|
|
]]></sqlcmd>
|
|
</NODE>
|
|
<NODE label="Profils">
|
|
<sqlcmd><![CDATA[
|
|
|
|
DROP TABLE IF EXISTS w_profils
|
|
;
|
|
|
|
CREATE TEMP TABLE w_profils AS
|
|
select
|
|
row_number() over () as row_id,
|
|
0 as profil_id,
|
|
0 as contrat_id,
|
|
0 as contrat_mois_id,
|
|
0 as salarie_id,
|
|
w_hst.numeroemploye,
|
|
employes.matricule,
|
|
w_hst.mois_paie as mois,
|
|
greatest(w_hst.date_debut, w_cnt_mois.cnt_date_debut) as date_debut,
|
|
least(w_hst.date_fin, w_cnt_mois.cnt_date_fin) as date_fin,
|
|
employes.codeetablissement,
|
|
w_hst.ratio_theo,
|
|
-- **** contrat ****
|
|
w_cnt_mois.cti_cnt,
|
|
w_cnt_mois.ncnt,
|
|
w_cnt_mois.cnt_date_debut,
|
|
w_cnt_mois.cnt_date_fin,
|
|
-- **** bulletins ****
|
|
w_bul.cti_bul,
|
|
-- w_bul.date_debut as bul_date_debut,
|
|
-- w_bul.date_fin as bul_date_fin,
|
|
w_bul.date_paie,
|
|
w_bul.sequence,
|
|
case when w_cnt_mois.codemotifrupture = '32' then 1 else 0 end as est_hors_periode, -- il n'y a jamais de paie hors période de contrat dans Quadra : le logiciel l'interdit.
|
|
-- **** code original ****
|
|
chr(1)||'*' as motif_debut_code_original,
|
|
-- Utile pour les bulletins émis en fin de mois et/ou hors période de contrat (car le motif de fin de contrat n'est pas reporté dans l'historique des bulletins) :
|
|
coalesce(w_cnt_mois.codemotifrupture, chr(1)||'*') as motif_fin_code_original,
|
|
coalesce(lower(w_hst.tds59), chr(1)||'*') AS categorie_socio_professionnelle_code_original,
|
|
coalesce(w_hst.qualification_code, chr(1)||'*') AS qualification_code_original,
|
|
coalesce(w_hst.service, chr(1)||'*') AS service_code_original,
|
|
coalesce(w_hst.emploi_code, chr(1)||'*') AS code_emploi_code_original,
|
|
chr(1)||'*' AS grille_code_original,
|
|
coalesce(w_hst.classification, chr(1)||'*') AS grille_groupe_code_original,
|
|
chr(1)||'*' AS specialite_code_original,
|
|
chr(1)||'*' AS groupe_cotisant_code_original,
|
|
chr(1)||'*' AS section_analytique_code_original,
|
|
chr(1)||'*' AS section_analytique_paie_code_original,
|
|
chr(1)||'*' AS societe_interim_code_original,
|
|
coalesce(w_hst.statut_code, chr(1)||'*') AS statut_code_original,
|
|
coalesce(w_hst.cddcdi, chr(1)||'*') as type_contrat_code_original,
|
|
chr(1)||'*' AS type_horaire_code_original,
|
|
coalesce(w_hst.ttt, chr(1)||'*') AS type_temps_travail_code_original,
|
|
-- Champs réservés au public.
|
|
chr(1)||'*' AS cadre_emploi_code_original, -- public
|
|
chr(1)||'*' AS categorie_conge_code_original, -- public
|
|
chr(1)||'*' AS categorie_statutaire_code_original, -- public
|
|
chr(1)||'*' AS commission_paritaire_code_original, -- public
|
|
chr(1)||'*' AS compte_salarie_code_original, -- public
|
|
chr(1)||'*' AS filiere_code_original, -- public
|
|
chr(1)||'*' AS lettre_budgetaire_code_original, -- public
|
|
chr(1)||'*' AS unite_fonctionnelle_code_original -- public
|
|
from w_hst
|
|
join prod_quadrarh.employes on 1=1
|
|
and employes.numero = w_hst.numeroemploye
|
|
and employes.matricule NOT ilike '%'||chr(178)||'%'
|
|
join w_bul on true
|
|
and w_bul.numeroemploye = w_hst.numeroemploye
|
|
and w_bul.mois_paie = w_hst.mois_paie
|
|
and w_bul.sequence = w_hst.sequence
|
|
-- join w_cnt on true
|
|
-- and w_cnt.numeroemploye = w_hst.numeroemploye
|
|
-- and w_cnt.sequence = w_hst.sequence
|
|
-- and w_hst.mois_paie between w_cnt.mois_debut and w_cnt.mois_fin
|
|
join w_cnt_mois on true
|
|
and w_cnt_mois.numeroemploye = w_hst.numeroemploye
|
|
and w_cnt_mois.sequence = w_hst.sequence
|
|
and w_cnt_mois.mois= w_hst.mois_paie
|
|
;
|
|
|
|
]]></sqlcmd>
|
|
</NODE>
|
|
<NODE name="PROFIL" type="common" />
|
|
<NODE label="Salariés">
|
|
<sqlcmd><![CDATA[
|
|
|
|
DROP TABLE IF EXISTS w_salaries
|
|
;
|
|
|
|
CREATE TEMP TABLE w_salaries AS
|
|
select
|
|
rhp('finess') AS finess,
|
|
coalesce(nommarital, nomnaissance) as nom,
|
|
nomnaissance as nom_naissance,
|
|
prenom,
|
|
datenaissance::date as date_naissance,
|
|
case when sexe = 1 then 'M' else 'F' end as sexe,
|
|
matricule,
|
|
matricule as matricule_planning,
|
|
matricule as code,
|
|
numero as code_original,
|
|
numeroinsee as nir,
|
|
t_etablissements.entreprise_id,
|
|
0 as nationalite_id,
|
|
0 as code_postal_id,
|
|
0 AS situation_famille_id,
|
|
0 AS profil_id,
|
|
null::date AS date_debut,
|
|
null::date AS date_fin,
|
|
null::date as date_entree_ets,
|
|
null::date as date_sortie_ets,
|
|
-- Champs dédiés au public.
|
|
null::date AS date_entree_fp,
|
|
null::date AS date_entree_fph,
|
|
0 AS no_adeli,
|
|
0 AS code_cotisation_id,
|
|
0 AS matricule_retraite
|
|
from prod_quadrarh.employes
|
|
join prod_quadrarh.etablissements on etablissements.codeetablissement = employes.codeetablissement
|
|
JOIN rh.t_etablissements ON t_etablissements.code_original = etablissements.siret
|
|
where matricule NOT ilike '%'||chr(178)||'%'
|
|
;
|
|
|
|
]]></sqlcmd>
|
|
</NODE>
|
|
<NODE name="SALARIE" type="common" />
|
|
<NODE label="Salariés (màj oid)">
|
|
<sqlcmd><![CDATA[
|
|
|
|
UPDATE w_profils SET
|
|
salarie_id = p_salaries.oid
|
|
FROM rh.p_salaries
|
|
WHERE w_profils.matricule = p_salaries.matricule
|
|
;
|
|
|
|
]]></sqlcmd>
|
|
</NODE>
|
|
<NODE label="Contrats">
|
|
<sqlcmd><![CDATA[
|
|
|
|
TRUNCATE rh.p_contrats
|
|
;
|
|
|
|
ALTER SEQUENCE rh.s_contrats RESTART WITH 1
|
|
;
|
|
|
|
INSERT INTO rh.p_contrats(
|
|
salarie_id,
|
|
date_debut,
|
|
date_fin,
|
|
numero_contrat,
|
|
code_original,
|
|
etablissement_id,
|
|
profil_id)
|
|
SELECT
|
|
p_salaries.oid AS salarie_id,
|
|
MIN(w_cnt_mois.cnt_date_debut) AS date_debut,
|
|
MAX(w_cnt_mois.cnt_date_fin) AS date_fin,
|
|
MAX(w_cnt_mois.ncnt) AS numero_contrat,
|
|
w_cnt_mois.ncnt AS code_original,
|
|
MAX(t_etablissements.oid) AS etablissement_id,
|
|
0 as profil_id
|
|
FROM w_cnt_mois
|
|
JOIN rh.p_salaries ON p_salaries.code_original = w_cnt_mois.numeroemploye
|
|
JOIN rh.t_etablissements ON t_etablissements.entreprise_id = p_salaries.entreprise_id
|
|
GROUP BY 1,5
|
|
;
|
|
|
|
-- Màj de l'ancienneté.
|
|
UPDATE rh.p_contrats SET
|
|
anciennete_anterieure_jours = subq.anciennete_anterieure_jours,
|
|
anciennete_anterieure_calculee_mois = subq.anciennete_anterieure_calculee_mois
|
|
FROM (
|
|
select
|
|
numero_contrat,
|
|
coalesce(sum(date_fin - date_debut + 1) over w, 0) AS anciennete_anterieure_jours,
|
|
coalesce(sum(date_fin - date_debut + 1) over w / 30::numeric, 0) AS anciennete_anterieure_calculee_mois
|
|
from rh.p_contrats
|
|
window w as (partition by salarie_id order by date_debut rows between UNBOUNDED PRECEDING and 1 preceding)) 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(
|
|
salarie_id,
|
|
contrat_id,
|
|
profil_id,
|
|
code_original,
|
|
mois_activite,
|
|
date_debut,
|
|
date_fin,
|
|
nombre_entrees,
|
|
nombre_departs,
|
|
nombre_debut_contrat,
|
|
nombre_fin_contrat,
|
|
est_hors_periode, -- bulletins de paie hors période de contrat.
|
|
present_debut_mois,
|
|
present_fin_mois,
|
|
equivalent_temps_plein,
|
|
age_id,
|
|
age_jours,
|
|
anciennete_jours,
|
|
anciennete_mois,
|
|
anciennete_annee_id,
|
|
etablissement_id)
|
|
SELECT
|
|
p_contrats.salarie_id,
|
|
p_contrats.oid as contrat_id,
|
|
w_profils.profil_id,
|
|
w_profils.row_id,
|
|
w_profils.mois as mois_activite,
|
|
w_profils.date_debut,
|
|
least(w_profils.date_fin, base.cti_last_day(w_profils.date_debut)) as date_fin,
|
|
0 as nombre_entrees,
|
|
0 as nombre_departs,
|
|
case when w_profils.cnt_date_debut between w_profils.date_debut and w_profils.date_fin then (case when w_profils.est_hors_periode = 1 then 0 else 1 end) else 0 end as nombre_debut_contrat,
|
|
case when w_profils.cnt_date_fin between w_profils.date_debut and w_profils.date_fin then (case when w_profils.est_hors_periode = 1 then 0 else 1 end) else 0 end as nombre_fin_contrat,
|
|
w_profils.est_hors_periode,
|
|
case when w_profils.cnt_date_debut > base.cti_first_day((w_profils.mois::text||'01')::date) then 0 else (case when w_profils.est_hors_periode = 1 then 0 else 1 end) end as present_debut_mois,
|
|
case when w_profils.cnt_date_fin < base.cti_last_day((w_profils.mois::text||'01')::date) then 0 else (case when w_profils.est_hors_periode = 1 then 0 else 1 end) end as present_fin_mois,
|
|
1 as equivalent_temps_plein, -- ! Mettre le bon ETP.
|
|
base.cti_age(least(w_profils.date_fin, w_profils.cnt_date_fin)::date, coalesce(p_salaries.date_naissance, '1962-04-18'::date), 'ny') AS age_id,
|
|
least(w_profils.date_fin, w_profils.cnt_date_fin)::date - coalesce(p_salaries.date_naissance, '1962-04-18'::date) AS age_jours,
|
|
p_contrats.anciennete_anterieure_jours
|
|
+ (w_profils.date_fin - w_profils.cnt_date_debut)
|
|
+ 1
|
|
AS anciennete_jours,
|
|
base.cti_age(date_trunc('month', w_profils.date_fin::date)::date, date_trunc('month', w_profils.cnt_date_debut)::date, 'nm')
|
|
+ p_contrats.anciennete_anterieure_calculee_mois + 1 AS anciennete_mois,
|
|
floor((base.cti_age(date_trunc('month', w_profils.date_fin::date)::date, date_trunc('month', w_profils.cnt_date_debut)::date, 'nm')
|
|
+ p_contrats.anciennete_anterieure_calculee_mois + 1) / 12) AS anciennete_annee_id,
|
|
p_contrats.etablissement_id
|
|
FROM w_profils
|
|
JOIN rh.p_contrats on p_contrats.code_original = w_profils.ncnt
|
|
JOIN rh.p_salaries on p_salaries.oid = p_contrats.salarie_id
|
|
;
|
|
|
|
-- On renseigne les id de contrats de w_profils.
|
|
UPDATE w_profils
|
|
SET contrat_id = p_contrats_mois.contrat_id,
|
|
contrat_mois_id = p_contrats_mois.oid
|
|
FROM rh.p_contrats_mois
|
|
WHERE w_profils.row_id = p_contrats_mois.code_original
|
|
;
|
|
|
|
]]></sqlcmd>
|
|
</NODE>
|
|
<NODE label="Historique de la paie">
|
|
<sqlcmd><![CDATA[
|
|
|
|
DROP TABLE IF EXISTS w_hp_0
|
|
;
|
|
|
|
CREATE TEMP TABLE w_hp_0 AS
|
|
select
|
|
numeroemploye,
|
|
periode::date as date_paie,
|
|
indiceperiode as sequence,
|
|
to_char(periode::date, 'YYYYMM')::int as mois_paie,
|
|
code||'_'||case when code = '.IJS' then (case when strpos(libelle, 'nette') > 0 then 'NET' else 'BRUT' end) else typeabsence end as code,
|
|
-- libelle,
|
|
case when code = '.NAP' then montantglobal::numeric else montant2::numeric end as base,
|
|
montant1::numeric as nombre,
|
|
montantsalarial::numeric as tx_sal,
|
|
coalesce(nullif(round(montant2::numeric * montant1::numeric, 2), 0), round(montant2::numeric * montantsalarial::numeric / 100.0 , 2)) as mt_sal,
|
|
(montantglobal::numeric - montantsalarial::numeric) as tx_pat,
|
|
round(montant2::numeric * (montantglobal::numeric - montantsalarial::numeric) / 100.0 , 2) as mt_pat
|
|
from prod_quadrarh.lignesbulletin
|
|
where to_char(periode::date, 'YYYY')::int > 2015
|
|
;
|
|
|
|
-- Régul pour Almaviva
|
|
UPDATE w_hp_0
|
|
SET base = 0
|
|
WHERE code = '.BAS_0' AND nombre < 1.1 AND current_database() IN ('icti_548','icti_549','icti_550','icti_551','icti_552','icti_553','icti_554')
|
|
;
|
|
|
|
DROP TABLE IF EXISTS w_hp
|
|
;
|
|
|
|
CREATE TEMP TABLE w_hp AS
|
|
SELECT
|
|
w_profils.contrat_mois_id,
|
|
w_profils.contrat_id,
|
|
w_profils.salarie_id,
|
|
w_profils.profil_id,
|
|
w_profils.matricule AS code_original,
|
|
w_profils.matricule AS matricule,
|
|
w_profils.numeroemploye,
|
|
w_hp_0.sequence,
|
|
w_profils.date_debut,
|
|
least(w_profils.date_fin, base.cti_last_day(w_profils.date_debut)) as date_fin,
|
|
w_profils.date_paie,
|
|
w_profils.mois,
|
|
w_hp_0.code,
|
|
t_rubriques.oid AS rubrique_id,
|
|
t_rubriques.p_detail,
|
|
t_rubriques.p_cumul,
|
|
t_rubriques.c_base
|
|
* case when @t_rubriques.c_base != 1 then coalesce(case when proratiser_conversion then w_profils.ratio_theo else 1.0 end, 1.0) else 1.0 end
|
|
* CASE WHEN p_base THEN (CASE s_base
|
|
WHEN 0 THEN w_hp_0.nombre
|
|
WHEN 1 THEN w_hp_0.base
|
|
WHEN 2 THEN w_hp_0.tx_sal
|
|
WHEN 3 THEN w_hp_0.mt_sal
|
|
WHEN 4 THEN w_hp_0.tx_pat
|
|
WHEN 5 THEN w_hp_0.mt_pat
|
|
WHEN 6 THEN w_hp_0.mt_sal + w_hp_0.mt_pat
|
|
WHEN 7 THEN w_hp_0.mt_sal - w_hp_0.mt_pat
|
|
WHEN 8 THEN w_hp_0.mt_pat - w_hp_0.mt_sal
|
|
END) else 0 end AS base,
|
|
t_rubriques.c_nombre
|
|
* case when @t_rubriques.c_nombre != 1 then coalesce(case when proratiser_conversion then w_profils.ratio_theo else 1.0 end, 1.0) else 1.0 end
|
|
* CASE WHEN p_nombre THEN (CASE s_nombre
|
|
WHEN 0 THEN w_hp_0.nombre
|
|
WHEN 1 THEN w_hp_0.base
|
|
WHEN 2 THEN w_hp_0.tx_sal
|
|
WHEN 3 THEN w_hp_0.mt_sal
|
|
WHEN 4 THEN w_hp_0.tx_pat
|
|
WHEN 5 THEN w_hp_0.mt_pat
|
|
WHEN 6 THEN w_hp_0.mt_sal + w_hp_0.mt_pat
|
|
WHEN 7 THEN w_hp_0.mt_sal - w_hp_0.mt_pat
|
|
WHEN 8 THEN w_hp_0.mt_pat - w_hp_0.mt_sal
|
|
END) else 0 end AS nombre,
|
|
t_rubriques.c_heures_contrat
|
|
* case when @t_rubriques.c_heures_contrat != 1 then coalesce(case when proratiser_conversion then w_profils.ratio_theo else 1.0 end, 1.0) else 1.0 end
|
|
* CASE WHEN p_heures_contrat
|
|
then (CASE s_heures_contrat
|
|
WHEN 0 THEN w_hp_0.nombre
|
|
WHEN 1 THEN w_hp_0.base
|
|
WHEN 2 THEN w_hp_0.tx_sal
|
|
WHEN 3 THEN w_hp_0.mt_sal
|
|
WHEN 4 THEN w_hp_0.tx_pat
|
|
WHEN 5 THEN w_hp_0.mt_pat
|
|
WHEN 6 THEN w_hp_0.mt_sal + w_hp_0.mt_pat
|
|
WHEN 7 THEN w_hp_0.mt_sal - w_hp_0.mt_pat
|
|
WHEN 8 THEN w_hp_0.mt_pat - w_hp_0.mt_sal
|
|
END)
|
|
else 0 end
|
|
AS heure_contrat,
|
|
t_rubriques.c_heures_payees
|
|
* case when @t_rubriques.c_heures_payees != 1 then coalesce(case when proratiser_conversion then w_profils.ratio_theo else 1.0 end, 1.0) else 1.0 end
|
|
* CASE WHEN p_heures_payees
|
|
then (CASE s_heures_payees
|
|
WHEN 0 THEN w_hp_0.nombre
|
|
WHEN 1 THEN w_hp_0.base
|
|
WHEN 2 THEN w_hp_0.tx_sal
|
|
WHEN 3 THEN w_hp_0.mt_sal
|
|
WHEN 4 THEN w_hp_0.tx_pat
|
|
WHEN 5 THEN w_hp_0.mt_pat
|
|
WHEN 6 THEN w_hp_0.mt_sal + w_hp_0.mt_pat
|
|
WHEN 7 THEN w_hp_0.mt_sal - w_hp_0.mt_pat
|
|
WHEN 8 THEN w_hp_0.mt_pat - w_hp_0.mt_sal
|
|
END) else 0 end AS heure_payee,
|
|
t_rubriques.c_heures_travaillees
|
|
* case when @t_rubriques.c_heures_travaillees != 1 then coalesce(case when proratiser_conversion then w_profils.ratio_theo else 1.0 end, 1.0) else 1.0 end
|
|
* CASE WHEN p_heures_travaillees
|
|
then (CASE s_heures_travaillees
|
|
WHEN 0 THEN w_hp_0.nombre
|
|
WHEN 1 THEN w_hp_0.base
|
|
WHEN 2 THEN w_hp_0.tx_sal
|
|
WHEN 3 THEN w_hp_0.mt_sal
|
|
WHEN 4 THEN w_hp_0.tx_pat
|
|
WHEN 5 THEN w_hp_0.mt_pat
|
|
WHEN 6 THEN w_hp_0.mt_sal + w_hp_0.mt_pat
|
|
WHEN 7 THEN w_hp_0.mt_sal - w_hp_0.mt_pat
|
|
WHEN 8 THEN w_hp_0.mt_pat - w_hp_0.mt_sal
|
|
END) else 0 end AS heure_travaillee,
|
|
t_rubriques.c_masse_salariale
|
|
* (CASE WHEN p_masse_salariale THEN
|
|
(CASE s_masse_salariale
|
|
WHEN 0 THEN w_hp_0.nombre
|
|
WHEN 1 THEN w_hp_0.base
|
|
WHEN 2 THEN w_hp_0.tx_sal
|
|
WHEN 3 THEN w_hp_0.mt_sal
|
|
WHEN 4 THEN w_hp_0.tx_pat
|
|
WHEN 5 THEN w_hp_0.mt_pat
|
|
WHEN 6 THEN w_hp_0.mt_sal + w_hp_0.mt_pat
|
|
WHEN 7 THEN w_hp_0.mt_sal - w_hp_0.mt_pat
|
|
WHEN 8 THEN w_hp_0.mt_pat - w_hp_0.mt_sal
|
|
END)
|
|
else 0 end) AS masse_salariale,
|
|
t_rubriques.c_brut
|
|
* (CASE WHEN p_brut THEN
|
|
(CASE s_brut
|
|
WHEN 0 THEN w_hp_0.nombre
|
|
WHEN 1 THEN w_hp_0.base
|
|
WHEN 2 THEN w_hp_0.tx_sal
|
|
WHEN 3 THEN w_hp_0.mt_sal
|
|
WHEN 4 THEN w_hp_0.tx_pat
|
|
WHEN 5 THEN w_hp_0.mt_pat
|
|
WHEN 6 THEN w_hp_0.mt_sal + w_hp_0.mt_pat
|
|
WHEN 7 THEN w_hp_0.mt_sal - w_hp_0.mt_pat
|
|
WHEN 8 THEN w_hp_0.mt_pat - w_hp_0.mt_sal
|
|
END)
|
|
else 0 end) AS montant_brut,
|
|
t_rubriques.c_frais_imposables
|
|
* (case when p_frais_imposables then
|
|
(CASE s_frais_imposables
|
|
WHEN 0 THEN w_hp_0.nombre
|
|
WHEN 1 THEN w_hp_0.base
|
|
WHEN 2 THEN w_hp_0.tx_sal
|
|
WHEN 3 THEN w_hp_0.mt_sal
|
|
WHEN 4 THEN w_hp_0.tx_pat
|
|
WHEN 5 THEN w_hp_0.mt_pat
|
|
WHEN 6 THEN w_hp_0.mt_sal + w_hp_0.mt_pat
|
|
WHEN 7 THEN w_hp_0.mt_sal - w_hp_0.mt_pat
|
|
WHEN 8 THEN w_hp_0.mt_pat - w_hp_0.mt_sal
|
|
END)
|
|
else 0 end) AS montant_frais_imposables,
|
|
t_rubriques.coefficient_txs * (case when p_cotisation_salarie then w_hp_0.tx_sal else 0 end) AS taux_sal,
|
|
t_rubriques.c_cotisation_salarie
|
|
* (case when p_cotisation_salarie then
|
|
(CASE s_cotisation_salarie
|
|
WHEN 0 THEN w_hp_0.nombre
|
|
WHEN 1 THEN w_hp_0.base
|
|
WHEN 2 THEN w_hp_0.tx_sal
|
|
WHEN 3 THEN w_hp_0.mt_sal
|
|
WHEN 4 THEN w_hp_0.tx_pat
|
|
WHEN 5 THEN w_hp_0.mt_pat
|
|
WHEN 6 THEN w_hp_0.mt_sal + w_hp_0.mt_pat
|
|
WHEN 7 THEN w_hp_0.mt_sal - w_hp_0.mt_pat
|
|
WHEN 8 THEN w_hp_0.mt_pat - w_hp_0.mt_sal
|
|
END)
|
|
else 0 end) AS montant_cot_sal,
|
|
t_rubriques.coefficient_txp * (case when p_cotisation_patronale then w_hp_0.tx_pat else 0 end) AS taux_pat,
|
|
t_rubriques.c_cotisation_patronale
|
|
* (case when p_cotisation_patronale then
|
|
(CASE s_cotisation_patronale
|
|
WHEN 0 THEN w_hp_0.nombre
|
|
WHEN 1 THEN w_hp_0.base
|
|
WHEN 2 THEN w_hp_0.tx_sal
|
|
WHEN 3 THEN w_hp_0.mt_sal
|
|
WHEN 4 THEN w_hp_0.tx_pat
|
|
WHEN 5 THEN w_hp_0.mt_pat
|
|
WHEN 6 THEN w_hp_0.mt_sal + w_hp_0.mt_pat
|
|
WHEN 7 THEN w_hp_0.mt_sal - w_hp_0.mt_pat
|
|
WHEN 8 THEN w_hp_0.mt_pat - w_hp_0.mt_sal
|
|
END)
|
|
else 0 end) AS montant_cot_pat,
|
|
t_rubriques.c_od_net_salarie
|
|
* (CASE WHEN p_od_net_salarie THEN
|
|
(CASE s_od_net_salarie
|
|
WHEN 0 THEN w_hp_0.nombre
|
|
WHEN 1 THEN w_hp_0.base
|
|
WHEN 2 THEN w_hp_0.tx_sal
|
|
WHEN 3 THEN w_hp_0.mt_sal
|
|
WHEN 4 THEN w_hp_0.tx_pat
|
|
WHEN 5 THEN w_hp_0.mt_pat
|
|
WHEN 6 THEN w_hp_0.mt_sal + w_hp_0.mt_pat
|
|
WHEN 7 THEN w_hp_0.mt_sal - w_hp_0.mt_pat
|
|
WHEN 8 THEN w_hp_0.mt_pat - w_hp_0.mt_sal
|
|
END)
|
|
ELSE 0 END) AS od_net,
|
|
t_rubriques.c_od_net_patronale
|
|
* (CASE WHEN p_od_net_patronale THEN
|
|
(CASE s_od_net_patronale
|
|
WHEN 0 THEN w_hp_0.nombre
|
|
WHEN 1 THEN w_hp_0.base
|
|
WHEN 2 THEN w_hp_0.tx_sal
|
|
WHEN 3 THEN w_hp_0.mt_sal
|
|
WHEN 4 THEN w_hp_0.tx_pat
|
|
WHEN 5 THEN w_hp_0.mt_pat
|
|
WHEN 6 THEN w_hp_0.mt_sal + w_hp_0.mt_pat
|
|
WHEN 7 THEN w_hp_0.mt_sal - w_hp_0.mt_pat
|
|
WHEN 8 THEN w_hp_0.mt_pat - w_hp_0.mt_sal
|
|
END)
|
|
ELSE 0 END) AS od_net_p,
|
|
t_rubriques.c_avantage_nature
|
|
* (CASE WHEN p_avantage_nature THEN
|
|
(CASE s_avantage_nature
|
|
WHEN 0 THEN w_hp_0.nombre
|
|
WHEN 1 THEN w_hp_0.base
|
|
WHEN 2 THEN w_hp_0.tx_sal
|
|
WHEN 3 THEN w_hp_0.mt_sal
|
|
WHEN 4 THEN w_hp_0.tx_pat
|
|
WHEN 5 THEN w_hp_0.mt_pat
|
|
WHEN 6 THEN w_hp_0.mt_sal + w_hp_0.mt_pat
|
|
WHEN 7 THEN w_hp_0.mt_sal - w_hp_0.mt_pat
|
|
WHEN 8 THEN w_hp_0.mt_pat - w_hp_0.mt_sal
|
|
END)
|
|
ELSE 0 END) AS avt_nat,
|
|
t_rubriques.c_net_imposable
|
|
* (CASE WHEN p_net_imposable THEN
|
|
(CASE s_net_imposable
|
|
WHEN 0 THEN w_hp_0.nombre
|
|
WHEN 1 THEN w_hp_0.base
|
|
WHEN 2 THEN w_hp_0.tx_sal
|
|
WHEN 3 THEN w_hp_0.mt_sal
|
|
WHEN 4 THEN w_hp_0.tx_pat
|
|
WHEN 5 THEN w_hp_0.mt_pat
|
|
WHEN 6 THEN w_hp_0.mt_sal + w_hp_0.mt_pat
|
|
WHEN 7 THEN w_hp_0.mt_sal - w_hp_0.mt_pat
|
|
WHEN 8 THEN w_hp_0.mt_pat - w_hp_0.mt_sal
|
|
END)
|
|
ELSE 0 END) AS net_imposable,
|
|
t_rubriques.c_net_a_payer
|
|
* (CASE WHEN p_net_a_payer THEN
|
|
(CASE s_net_a_payer
|
|
WHEN 0 THEN w_hp_0.nombre
|
|
WHEN 1 THEN w_hp_0.base
|
|
WHEN 2 THEN w_hp_0.tx_sal
|
|
WHEN 3 THEN w_hp_0.mt_sal
|
|
WHEN 4 THEN w_hp_0.tx_pat
|
|
WHEN 5 THEN w_hp_0.mt_pat
|
|
WHEN 6 THEN w_hp_0.mt_sal + w_hp_0.mt_pat
|
|
WHEN 7 THEN w_hp_0.mt_sal - w_hp_0.mt_pat
|
|
WHEN 8 THEN w_hp_0.mt_pat - w_hp_0.mt_sal
|
|
END)
|
|
ELSE 0 END) AS net_a_payer
|
|
FROM w_hp_0
|
|
JOIN w_profils ON 1=1
|
|
AND w_profils.numeroemploye = w_hp_0.numeroemploye
|
|
AND w_profils.mois = w_hp_0.mois_paie
|
|
AND w_profils.sequence = w_hp_0.sequence
|
|
JOIN rh.t_rubriques ON t_rubriques.code_original = w_hp_0.code
|
|
where 1=1
|
|
-- AND t_hbns.datehist >= rhp('rhprovider_start')::date
|
|
-- Filtrer les lignes générées systématiquement tous les mois par Sage pour chaque salarié même s'il n'y a rien.
|
|
AND (false
|
|
OR p_nombre
|
|
OR p_base
|
|
OR p_heures_contrat
|
|
OR p_heures_payees
|
|
OR p_heures_travaillees
|
|
OR p_masse_salariale
|
|
OR p_brut
|
|
OR p_avantage_nature
|
|
OR p_frais_imposables
|
|
OR p_cotisation_salarie
|
|
OR p_cotisation_patronale
|
|
OR p_od_net_salarie
|
|
OR p_od_net_patronale
|
|
OR p_net_imposable
|
|
OR p_net_a_payer)
|
|
;
|
|
|
|
-- Génération paie
|
|
SELECT base.cti_stash_table_indexes('rh', 'p_historique_paie')
|
|
;
|
|
|
|
TRUNCATE rh.p_historique_paie
|
|
;
|
|
|
|
INSERT INTO rh.p_historique_paie(
|
|
code_original,
|
|
age_id,
|
|
base,
|
|
nombre,
|
|
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,
|
|
organisme_cotisation_id,
|
|
profil_id,
|
|
rubrique_id,
|
|
compte_id,
|
|
salarie_id,
|
|
taux_cotisation_patronale,
|
|
taux_cotisation_salarie)
|
|
SELECT
|
|
w_hp.matricule||w_hp.sequence||w_hp.date_paie::date as code_original,
|
|
date_part('year', age(w_hp.date_fin, date_naissance)) AS age_id,
|
|
w_hp.base,
|
|
w_hp.nombre,
|
|
w_hp.contrat_id,
|
|
w_hp.contrat_mois_id,
|
|
w_hp.date_paie,
|
|
w_hp.date_paie,
|
|
w_hp.date_paie AS date_paie,
|
|
w_hp.mois AS mois_activite,
|
|
w_hp.mois AS mois_paie,
|
|
w_hp.heure_contrat,
|
|
w_hp.heure_payee,
|
|
w_hp.heure_travaillee,
|
|
w_hp.avt_nat AS montant_avantage_nature,
|
|
w_hp.montant_brut AS montant_brut,
|
|
w_hp.masse_salariale as montant_masse_salariale,
|
|
w_hp.montant_cot_pat AS montant_cotisation_patronale,
|
|
w_hp.montant_cot_sal AS montant_cotisation_salarie,
|
|
w_hp.montant_frais_imposables,
|
|
w_hp.net_a_payer AS montant_net_a_payer_salarie,
|
|
w_hp.net_imposable AS montant_net_imposable_salarie,
|
|
w_hp.od_net AS montant_od_net_salarie,
|
|
0 AS organisme_cotisation_id,
|
|
w_hp.profil_id,
|
|
w_hp.rubrique_id,
|
|
0 AS compte_id,
|
|
w_hp.salarie_id,
|
|
w_hp.taux_pat AS taux_cotisation_patronale,
|
|
w_hp.taux_sal AS taux_cotisation_salarie
|
|
FROM w_hp
|
|
JOIN rh.p_salaries ON p_salaries.oid = w_hp.salarie_id
|
|
WHERE p_detail
|
|
;
|
|
|
|
SELECT base.cti_stash_pop_table_indexes('rh', 'p_historique_paie')
|
|
;
|
|
|
|
-- Création d'une table récapitulative des écarts à calculer par indicateur de paie (1 seule ligne).
|
|
DROP TABLE IF EXISTS w_cumul
|
|
;
|
|
|
|
CREATE TEMP TABLE w_cumul AS
|
|
SELECT
|
|
bool_or(p_cumul and p_avantage_nature) as total_avantage_nature,
|
|
bool_or(p_cumul and p_brut) as total_brut,
|
|
bool_or(p_cumul and p_masse_salariale) as total_masse_salariale,
|
|
bool_or(p_cumul and p_cotisation_patronale) as total_cot_pat,
|
|
bool_or(p_cumul and p_cotisation_salarie) as total_cot_sal,
|
|
bool_or(p_cumul and p_net_a_payer) as total_payer,
|
|
bool_or(p_cumul and p_net_imposable) as total_imposable,
|
|
bool_or(p_cumul and p_heures_contrat) as total_h_contrat,
|
|
bool_or(p_cumul and p_heures_payees) as total_h_payees,
|
|
bool_or(p_cumul and p_heures_travaillees) as total_h_travaillees
|
|
FROM rh.t_rubriques
|
|
;
|
|
|
|
-- Création d'une table temp qui regroupe tous les totaux à atteindre pour calculer l'écart
|
|
DROP TABLE IF EXISTS w_totaux
|
|
;
|
|
|
|
CREATE TEMP TABLE w_totaux AS
|
|
SELECT
|
|
w_hp.matricule||w_hp.sequence||w_hp.date_paie::date as code_original,
|
|
w_hp.matricule,
|
|
w_hp.date_paie as date,
|
|
w_hp.mois,
|
|
round(sum(case when p_cumul then avt_nat else 0 end), 2) AS hcum_avantage_nature,
|
|
round(sum(case when p_cumul then montant_brut else 0 end), 2) AS hcum_brut,
|
|
round(sum(case when p_cumul then masse_salariale else 0 end), 2) AS hcum_masse_salariale,
|
|
round(sum(case when p_cumul then montant_cot_pat else 0 end), 2) AS hcum_cotisation_patronale,
|
|
round(sum(case when p_cumul then montant_cot_sal else 0 end), 2) AS hcum_cotisation_salarie,
|
|
0::numeric AS hcum_frais_imposables,
|
|
round(sum(case when p_cumul then net_a_payer else 0 end), 2) AS hcum_net_a_payer_salarie,
|
|
round(sum(case when p_cumul then net_imposable else 0 end), 2) AS hcum_net_imposable_salarie,
|
|
sum(case when p_cumul then heure_contrat else 0 end) AS hcum_heures_contrat,
|
|
sum(case when p_cumul then heure_payee else 0 end) AS hcum_heures_payees,
|
|
sum(case when p_cumul then heure_travaillee else 0 end) AS hcum_heures_travaillees,
|
|
0::numeric AS montant_od_net_salarie
|
|
FROM w_hp
|
|
WHERE p_cumul
|
|
GROUP BY 1,2,3,4
|
|
;
|
|
|
|
-- A la demande de Mme CONSTANTIN, ajout des heures d'astreinte travaillees (B092 et BF92) au total des heures payées Quadra car mal paramétré dans Quadra.
|
|
WITH correction as(
|
|
SELECT
|
|
w_hp.matricule||w_hp.sequence||w_hp.date_paie::date as code_original,
|
|
sum(base) AS heures_astreinte
|
|
FROM w_hp
|
|
WHERE code in ('B092_0', 'BF92_0')
|
|
GROUP BY 1
|
|
HAVING sum(base) != 0)
|
|
UPDATE w_totaux SET
|
|
hcum_heures_payees = hcum_heures_payees + heures_astreinte
|
|
FROM correction
|
|
WHERE w_totaux.code_original = correction.code_original
|
|
;
|
|
|
|
-- Insérer 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 (
|
|
code_original,
|
|
age_id,
|
|
contrat_id,
|
|
contrat_mois_id,
|
|
date_debut,
|
|
date_fin,
|
|
date_paie,
|
|
mois_activite,
|
|
mois_paie,
|
|
base,
|
|
nombre,
|
|
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,
|
|
organisme_cotisation_id,
|
|
profil_id,
|
|
rubrique_id,
|
|
compte_id,
|
|
salarie_id,
|
|
taux_cotisation_patronale,
|
|
taux_cotisation_salarie)
|
|
SELECT
|
|
subq.code_original,
|
|
subq.age_id,
|
|
subq.contrat_id,
|
|
subq.contrat_mois_id,
|
|
subq.date_debut,
|
|
subq.date_fin,
|
|
subq.date_paie,
|
|
subq.mois_activite,
|
|
subq.mois_paie,
|
|
0 AS base,
|
|
0 AS nombre,
|
|
case when total_h_contrat then COALESCE(hcum_heures_contrat, 0) - subq.heure_contrat else 0.0 end AS heure_contrat,
|
|
case when total_h_payees then COALESCE(hcum_heures_payees,0) - subq.heure_payee else 0.0 end AS heure_payee,
|
|
case when total_h_travaillees then COALESCE(hcum_heures_travaillees,0) - subq.heure_travaillee else 0.0 end AS heure_travaillee,
|
|
case when total_avantage_nature then COALESCE(hcum_avantage_nature,0) - subq.montant_avantage_nature else 0.0 end AS montant_avantage_nature,
|
|
case when total_brut then COALESCE(hcum_brut,0) - subq.montant_brut else 0.0 end AS montant_brut,
|
|
case when total_masse_salariale then COALESCE(hcum_masse_salariale, 0) - subq.montant_masse_salariale else 0.0 end AS montant_masse_salariale,
|
|
case when total_cot_pat then COALESCE(hcum_cotisation_patronale,0) - subq.montant_cotisation_patronale else 0.0 end AS montant_cotisation_patronale,
|
|
case when total_cot_sal then COALESCE(hcum_cotisation_salarie,0) - subq.montant_cotisation_salarie else 0.0 end AS montant_cotisation_salarie,
|
|
0 AS montant_frais_imposables,
|
|
case when total_payer then COALESCE(hcum_net_a_payer_salarie,0) - subq.montant_net_a_payer_salarie else 0.0 end AS montant_net_a_payer_salarie,
|
|
case when total_imposable then COALESCE(hcum_net_imposable_salarie,0) - subq.montant_net_imposable_salarie else 0.0 end AS montant_net_imposable_salarie,
|
|
0 AS montant_od_net_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,
|
|
0 AS compte_id,
|
|
subq.salarie_id AS salarie_id,
|
|
0 AS taux_cotisation_patronale,
|
|
0 AS taux_cotisation_salarie
|
|
FROM (
|
|
SELECT
|
|
p_historique_paie.code_original,
|
|
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 base,
|
|
0 AS nombre,
|
|
sum(heure_contrat) AS heure_contrat,
|
|
sum(heure_payee) AS heure_payee,
|
|
sum(heure_travaillee) AS heure_travaillee,
|
|
sum(montant_avantage_nature) AS montant_avantage_nature,
|
|
sum(montant_brut) AS montant_brut,
|
|
sum(montant_masse_salariale) AS montant_masse_salariale,
|
|
sum(montant_cotisation_patronale) AS montant_cotisation_patronale,
|
|
sum(montant_cotisation_salarie) AS montant_cotisation_salarie,
|
|
0 AS montant_frais_imposables,
|
|
sum(montant_net_a_payer_salarie) AS montant_net_a_payer_salarie,
|
|
sum(montant_net_imposable_salarie) AS montant_net_imposable_salarie,
|
|
0 AS montant_od_net_salarie,
|
|
p_historique_paie.organisme_cotisation_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,11, 24,25,26,27) AS subq
|
|
JOIN w_totaux ON w_totaux.code_original = subq.code_original
|
|
JOIN w_cumul ON true
|
|
WHERE 1!=1
|
|
OR case when total_avantage_nature then COALESCE(hcum_avantage_nature,0) - subq.montant_avantage_nature != 0 else false end
|
|
OR case when total_brut then COALESCE(hcum_brut,0) - subq.montant_brut != 0 else false end
|
|
OR case when total_masse_salariale then COALESCE(hcum_masse_salariale,0) - subq.montant_masse_salariale != 0 else false end
|
|
OR case when total_payer then COALESCE(hcum_net_a_payer_salarie,0) - subq.montant_net_a_payer_salarie != 0 else false end
|
|
OR case when total_imposable then COALESCE(hcum_net_imposable_salarie,0) - subq.montant_net_imposable_salarie != 0 else false end
|
|
OR case when total_cot_pat then COALESCE(hcum_cotisation_patronale,0) - subq.montant_cotisation_patronale != 0 else false end
|
|
OR case when total_cot_sal then COALESCE(hcum_cotisation_salarie,0) - subq.montant_cotisation_salarie != 0 else false end
|
|
OR case when total_h_contrat then COALESCE(hcum_heures_contrat, 0) - subq.heure_contrat != 0 else false end
|
|
OR case when total_h_payees then COALESCE(hcum_heures_payees,0) - subq.heure_payee != 0 else false end
|
|
OR case when total_h_travaillees then COALESCE(hcum_heures_travaillees,0) - subq.heure_travaillee != 0 else false end
|
|
;
|
|
|
|
]]></sqlcmd>
|
|
</NODE>
|
|
<NODE label="Ventilation des profils">
|
|
<sqlcmd><![CDATA[
|
|
|
|
-- Alimentation des profils simultanés.
|
|
TRUNCATE rh.p_profil_contrat_mois
|
|
;
|
|
|
|
INSERT INTO rh.p_profil_contrat_mois (
|
|
profil_id,
|
|
contrat_mois_id,
|
|
salarie_id,
|
|
ratio,
|
|
mois)
|
|
SELECT
|
|
p_contrats_mois.profil_id,
|
|
p_contrats_mois.oid AS contrat_mois_id,
|
|
p_contrats_mois.salarie_id,
|
|
1 AS ratio,
|
|
p_contrats_mois.mois_activite
|
|
FROM rh.p_contrats_mois
|
|
--JOIN w_profils ON w_profils.row_id = p_contrats_mois.code_original
|
|
GROUP BY 1,2,3,4,5
|
|
;
|
|
|
|
]]></sqlcmd>
|
|
</NODE>
|
|
</NODE>
|
|
<NODE name="POST" label="POST-TRAITEMENTS">
|
|
<NODE name="DIVERS" type="common"/>
|
|
<NODE label="Mise à jour de la table Divers (mois en cours)">
|
|
<sqlcmd><![CDATA[
|
|
|
|
-- Màj du mois non clôturé.
|
|
-- DELETE FROM rh.t_divers
|
|
-- WHERE code = 'MOIS_EN_COURS'
|
|
-- ;
|
|
|
|
-- INSERT INTO rh.t_divers(
|
|
-- code,
|
|
-- texte,
|
|
-- valeur,
|
|
-- valeur_date,
|
|
-- description)
|
|
-- VALUES(
|
|
-- 'MOIS_EN_COURS',
|
|
-- 'Mois en cours (non clôturé).',
|
|
-- (SELECT to_char(date_paie_encours, 'YYYYMM') FROM w_periode),
|
|
-- (SELECT date_paie_encours FROM w_periode),
|
|
-- 'Mois en cours (non clôturé).'
|
|
-- )
|
|
-- ;
|
|
|
|
]]></sqlcmd>
|
|
</NODE>
|
|
<NODE name="POST" type="common"/>
|
|
</NODE>
|
|
<NODE name="VACUUM" label="REORGANISATION BASE DE DONNEES">
|
|
<NODE name="VACUUM" type="common" />
|
|
</NODE>
|
|
<NODE name="RAZ" label="RAZ BASE">
|
|
<NODE name="RAZ" type="common" />
|
|
</NODE>
|
|
<NODE name="RAZ_ALL" label="RAZ ALL">
|
|
<NODE name="RAZ_ALL" type="common" />
|
|
</NODE>
|
|
</ROOT>
|