<?xml version="1.0" encoding="ISO-8859-15"?>
|
|
<ROOT>
|
|
<NODE name="INIT" label="INITIALISATIONS">
|
|
|
|
<NODE label="Consolidation prodsgbd">
|
|
<sqlcmd><![CDATA[
|
|
|
|
SELECT base.cti_execute('ALTER TABLE '||pg_namespace.nspname||'.'||pg_class.RELNAME||' INHERIT prod_cador.'||pg_class.RELNAME||';',1)
|
|
FROM pg_class
|
|
JOIN pg_namespace on pg_namespace.oid = pg_class.relnamespace
|
|
JOIN pg_class pg_class_parent ON pg_class_parent.RELNAME = pg_class.RELNAME
|
|
JOIN pg_namespace pg_namespace_parent on pg_namespace_parent.oid = pg_class_parent.relnamespace
|
|
LEFT JOIN pg_inherits ON pg_class.OID = INHRELID
|
|
WHERE pg_namespace.NSPNAME LIKE 'prod\_cador\_%' AND
|
|
pg_namespace_parent.NSPNAME = 'prod_cador' AND
|
|
INHRELID IS NULL
|
|
;
|
|
|
|
]]></sqlcmd>
|
|
</NODE>
|
|
|
|
<NODE label="Pré-traitements">
|
|
<sqlcmd><![CDATA[
|
|
|
|
DROP TABLE IF EXISTS w_bul
|
|
;
|
|
|
|
CREATE TEMP TABLE w_bul AS
|
|
select
|
|
to_char(bul_date_regl::date, 'YYYYMM')::int as mois_paie,
|
|
bul_periode,
|
|
bul_code,
|
|
bul_deb::date,
|
|
bul_fin::date,
|
|
bul_date_regl::date,
|
|
bul_grp,
|
|
act_code::bigint,
|
|
bul_reg
|
|
from prod_cador.bulletin
|
|
where bul_periode::int != 0
|
|
;
|
|
|
|
DROP TABLE IF EXISTS w_hst
|
|
;
|
|
|
|
CREATE TEMP TABLE w_hst AS
|
|
select
|
|
act_code::bigint,
|
|
eta_code,
|
|
sal_code,
|
|
(max(array[substr(pg_namespace.nspname, 12) , act_date_ent]))[2]::date as act_date_ent,
|
|
(max(array[substr(pg_namespace.nspname, 12) , act_date_sor]))[2]::date as act_date_sor,
|
|
(max(array[substr(pg_namespace.nspname, 12) , act_type_contr]))[2] as act_type_contr,
|
|
(max(array[substr(pg_namespace.nspname, 12) , act_coeff_effect]))[2]::numeric as act_coeff_effect,
|
|
''::text as ttt,
|
|
''::text as ttt_libelle,
|
|
''::text as ttt_libelle_court,
|
|
(max(array[substr(pg_namespace.nspname, 12) , act_emploi]))[2] as act_emploi,
|
|
(max(array[substr(pg_namespace.nspname, 12) , act_insee]))[2] as act_insee,
|
|
(max(array[substr(pg_namespace.nspname, 12) , act_motif_debut]))[2] as act_motif_debut,
|
|
(max(array[substr(pg_namespace.nspname, 12) , act_motif_fin]))[2] as act_motif_fin,
|
|
(max(array[substr(pg_namespace.nspname, 12) , act_contrat_travail]))[2] as act_contrat_travail,
|
|
(max(array[substr(pg_namespace.nspname, 12) , act_statut_prof]))[2] as act_statut_prof,
|
|
(max(array[substr(pg_namespace.nspname, 12) , act_qualif]))[2] as act_qualif
|
|
from prod_cador.activite
|
|
join pg_class on activite.tableoid = pg_class.oid
|
|
join pg_namespace on pg_namespace.oid = pg_class.relnamespace
|
|
group by 1,2,3
|
|
;
|
|
|
|
update w_hst set
|
|
act_date_sor = '2099-12-31'::date
|
|
where to_char(act_date_sor, 'YYYY') = '1899'
|
|
;
|
|
|
|
update w_hst set
|
|
ttt = case when act_coeff_effect = 1 then 'TC100' else 'TP'||lpad((act_coeff_effect* 100)::int::text, 3, '0') end,
|
|
ttt_libelle = case when act_coeff_effect = 1 then 'Temps Complet' else 'Temps Partiel '||lpad((act_coeff_effect* 100)::int::text, 3, '0')|| ' %' end,
|
|
ttt_libelle_court = case when act_coeff_effect = 1 then 'TC' else 'TP '||lpad((act_coeff_effect* 100)::int::text, 3, '0')|| ' %' end
|
|
;
|
|
|
|
DROP TABLE IF EXISTS w_hp_0
|
|
;
|
|
|
|
CREATE TEMP TABLE w_hp_0 AS
|
|
select
|
|
bul_code,
|
|
rub_code,
|
|
lb_code,
|
|
lb_mt_1::numeric as base,
|
|
0::numeric as nombre,
|
|
lb_mt_2::numeric as tx_sal,
|
|
case when current_database() = 'icti_502' and rub_code = '9950' then lb_mt_7::numeric else lb_mt_3::numeric end as mt_sal,
|
|
lb_mt_5::numeric as tx_pat,
|
|
lb_mt_6::numeric as mt_pat
|
|
from prod_cador.ligne_bulletin
|
|
where false
|
|
or lb_mt_1::numeric != 0
|
|
-- or lb_mt_2::numeric != 0
|
|
or case when current_database() = 'icti_502' and rub_code = '9950' then lb_mt_7::numeric else lb_mt_3::numeric end != 0
|
|
-- or lb_mt_5::numeric != 0
|
|
or lb_mt_6::numeric != 0
|
|
;
|
|
|
|
]]></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)
|
|
with eta as (
|
|
select cc_code, eta_code, eta_siren, eta_nic, max(tmp_eta_rs) as rs
|
|
from prod_cador.etablissement
|
|
group by 1,2,3,4)
|
|
select
|
|
cc_code,
|
|
eta_siren,
|
|
max(rs),
|
|
substr(max(rs), 1, 50)
|
|
from eta
|
|
where 1=1
|
|
AND cc_code NOT IN (SELECT code_original FROM rh.t_entreprises WHERE code_original IS NOT NULL)
|
|
AND (1!=1
|
|
OR eta_siren IN (SELECT rhp_in('siren')) -- Soit un ou plusieurs SIREN ont été défini,
|
|
OR eta_siren||eta_nic IN (SELECT rhp_in('siren')) -- et/ou soit un ou plusieurs SIRET,
|
|
OR eta_code 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)
|
|
with eta as (
|
|
select cc_code, eta_code, eta_siren, eta_nic, max(tmp_eta_rs) as rs
|
|
from prod_cador.etablissement
|
|
group by 1,2,3,4)
|
|
SELECT
|
|
eta_code,
|
|
eta_siren||eta_nic,
|
|
rs,
|
|
substr(rs, 1, 50),
|
|
t_entreprises.oid
|
|
FROM eta
|
|
JOIN rh.t_entreprises ON t_entreprises.code_original = eta.cc_code
|
|
where 1=1
|
|
AND eta_code NOT IN (SELECT code_original FROM rh.t_etablissements WHERE code_original IS NOT NULL)
|
|
AND (1!=1
|
|
OR eta_siren IN (SELECT rhp_in('siren')) -- Soit un ou plusieurs SIREN ont été défini,
|
|
OR eta_siren||eta_nic IN (SELECT rhp_in('siren')) -- et/ou soit un ou plusieurs SIRET,
|
|
OR eta_code IN (SELECT rhp_in('siren'))) -- et/ou soit un ou plusieurs codes établissement.
|
|
;
|
|
|
|
-- Màj des catégories socio-professionnelles
|
|
INSERT INTO rh.t_categories_socio_professionnelle (code_original, code, texte, texte_court)
|
|
SELECT lower(act_insee), lower(act_insee), lower(act_insee), substr(lower(act_insee), 1, 50)
|
|
FROM w_hst
|
|
WHERE 1=1
|
|
AND lower(act_insee) 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 act_motif_debut, act_motif_debut, act_motif_debut, substr(max(act_motif_debut),1,50)
|
|
FROM w_hst
|
|
WHERE act_motif_debut 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 act_motif_fin, act_motif_fin, act_motif_fin, substr(act_motif_fin, 1, 50)
|
|
FROM w_hst
|
|
WHERE act_motif_fin 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 substr(md5(act_emploi), 1, 5), substr(md5(act_emploi), 1, 5), act_emploi, substr(act_emploi, 1, 50)
|
|
FROM w_hst
|
|
WHERE substr(md5(act_emploi), 1, 5) NOT IN (SELECT code_original FROM rh.t_qualifications WHERE code_original IS NOT NULL)
|
|
GROUP BY 1,2,3,4
|
|
;
|
|
|
|
-- Màj des rubriques
|
|
INSERT INTO rh.t_rubriques(code_original, code, texte, texte_court, rang_edition)
|
|
with all_rubs as (
|
|
select rub_code, min(coalesce(lb_lib, lb_lib_memo, ''::text)) as rub_lib
|
|
from prod_cador.ligne_bulletin
|
|
group by 1)
|
|
SELECT rub_code, lpad(rub_code, 4, '0'), rub_lib, substr(rub_lib, 1, 50), -1
|
|
FROM all_rubs
|
|
WHERE rub_code 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 act_contrat_travail, act_contrat_travail, act_contrat_travail, substr(act_contrat_travail, 1, 50)
|
|
FROM w_hst
|
|
WHERE act_contrat_travail 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 act_statut_prof, act_statut_prof, act_statut_prof, substr(act_statut_prof, 1, 50)
|
|
FROM w_hst
|
|
WHERE act_statut_prof NOT IN (SELECT code_original FROM rh.t_statuts WHERE code_original IS NOT NULL)
|
|
GROUP BY 1,2,3,4
|
|
;
|
|
|
|
-- 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 substr(md5(act_emploi), 1, 5), substr(md5(act_emploi), 1, 5), act_emploi, substr(act_emploi, 1, 50)
|
|
FROM w_hst
|
|
WHERE substr(md5(act_emploi), 1, 5) 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 substr(md5(act_qualif), 1, 5), substr(md5(act_qualif), 1, 5), act_qualif, substr(act_qualif, 1, 50)
|
|
from w_hst
|
|
WHERE substr(md5(act_qualif), 1, 5) 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,
|
|
code,
|
|
NOT code::int between 7000 and 7999 AS p_detail,
|
|
true AS p_nombre,
|
|
true AS p_base,
|
|
false AS p_heures_contrat,
|
|
false AS p_heures_payees,
|
|
false AS p_heures_travaillees,
|
|
code::int < 2000 or code::int between 2100 and 4999 AS p_masse_salariale,
|
|
code::int < 2000 AS p_brut,
|
|
false AS p_avantage_nature,
|
|
false AS p_frais_imposables,
|
|
code::int between 2100 and 4999 as p_cotisation_salarie,
|
|
code::int between 2100 and 4999 as p_cotisation_patronale,
|
|
code::int between 5200 and 9949 and NOT code::int between 7000 and 7999 as p_od_net_salarie,
|
|
false AS p_od_net_patronale,
|
|
code::int < 2000 or code::int between 2100 and 5099 AS p_net_imposable,
|
|
code::int < 2000 or code::int between 2100 and 4999 or code::int between 5200 and 9949 and NOT code::int between 7000 and 7999 AS p_net_a_payer
|
|
from rh.t_rubriques
|
|
where 1=1
|
|
and t_rubriques.oid != 0
|
|
and t_rubriques.code not ilike 'C%'
|
|
) as subq
|
|
where 1=1
|
|
and t_rubriques.oid = subq.oid
|
|
and NOT t_rubriques.user_modified
|
|
;
|
|
|
|
]]></sqlcmd>
|
|
</NODE>
|
|
</NODE>
|
|
<NODE name="PROD" label="RECUPERATION DES DONNEES DE PRODUCTION">
|
|
<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.sal_code as matricule,
|
|
w_hst.act_code,
|
|
w_hst.act_date_ent AS cnt_date_debut,
|
|
w_hst.act_date_sor AS cnt_date_fin,
|
|
w_hst.eta_code,
|
|
w_hst.act_coeff_effect as ratio_theo,
|
|
w_bul.bul_code,
|
|
w_bul.bul_deb,
|
|
w_bul.bul_fin,
|
|
w_bul.bul_deb as date_debut,
|
|
w_bul.bul_fin as date_fin,
|
|
w_bul.mois_paie,
|
|
w_bul.mois_paie as mois,
|
|
w_bul.bul_date_regl as date_paie,
|
|
0 as est_hors_periode, -- il n'y a jamais de paie hors période de contrat dans Cador Expert : le logiciel l'interdit.
|
|
-- **** code original ****
|
|
coalesce(act_motif_debut, chr(1)||'*') as motif_debut_code_original,
|
|
coalesce(act_motif_fin, chr(1)||'*') as motif_fin_code_original,
|
|
coalesce(act_insee, chr(1)||'*') AS categorie_socio_professionnelle_code_original,
|
|
coalesce(substr(md5(act_emploi), 1, 5), chr(1)||'*') AS qualification_code_original,
|
|
coalesce(substr(md5(act_emploi), 1, 5), chr(1)||'*') AS service_code_original,
|
|
chr(1)||'*' AS code_emploi_code_original,
|
|
chr(1)||'*' AS grille_code_original,
|
|
coalesce(substr(md5(act_qualif), 1, 5), 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(act_statut_prof, chr(1)||'*') AS statut_code_original,
|
|
coalesce(act_contrat_travail, chr(1)||'*') as type_contrat_code_original,
|
|
chr(1)||'*' AS type_horaire_code_original,
|
|
coalesce(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 w_bul on w_bul.act_code = w_hst.act_code
|
|
;
|
|
|
|
]]></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,
|
|
sal_code as matricule,
|
|
sal_code as matricule_planning,
|
|
sal_code as code,
|
|
sal_code as code_original,
|
|
t_entreprises.oid as entreprise_id,
|
|
(max(array[substr(pg_namespace.nspname, 12) , coalesce(sal_nom_mar, sal_nom)]))[2] as nom,
|
|
(max(array[substr(pg_namespace.nspname, 12) , sal_nom]))[2] as nom_naissance,
|
|
(max(array[substr(pg_namespace.nspname, 12) , sal_pre]))[2] as prenom,
|
|
(max(array[substr(pg_namespace.nspname, 12) , sal_date_naiss]))[2]::date as date_naissance,
|
|
case when (max(array[substr(pg_namespace.nspname, 12) , sal_titre]))[2] = 'M.' then 'M' else 'F' end as sexe,
|
|
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,
|
|
(max(array[substr(pg_namespace.nspname, 12) , sal_date_ent]))[2]::date as date_entree_ets,
|
|
null::date as date_sortie_ets,
|
|
(max(array[substr(pg_namespace.nspname, 12) , sal_secu]))[2]::text as nir,
|
|
-- 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_cador.salarie
|
|
JOIN rh.t_entreprises ON case when current_database() = 'icti_502' then t_entreprises.oid > 0 else t_entreprises.code_original = salarie.cc_code end
|
|
join pg_class on salarie.tableoid = pg_class.oid
|
|
join pg_namespace on pg_namespace.oid = pg_class.relnamespace
|
|
-- sal_postal,
|
|
-- sal_secu,
|
|
-- sal_natio,
|
|
-- sal_situ_fam
|
|
group by 1,2,3,4,5,6, 12,13,14,15,16,17,19,21,22,23,24,25
|
|
;
|
|
|
|
]]></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,
|
|
w_profils.cnt_date_debut AS date_debut,
|
|
w_profils.cnt_date_fin AS date_fin,
|
|
w_profils.act_code AS numero_contrat,
|
|
w_profils.act_code AS code_original,
|
|
t_etablissements.oid AS etablissement_id,
|
|
w_profils.profil_id
|
|
FROM w_profils
|
|
JOIN rh.p_salaries ON p_salaries.code_original = w_profils.matricule
|
|
JOIN rh.t_etablissements ON t_etablissements.entreprise_id = p_salaries.entreprise_id AND t_etablissements.code_original = eta_code
|
|
GROUP BY 1,2,3,4,5,6,7
|
|
;
|
|
|
|
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_paie as mois_activite,
|
|
w_profils.bul_deb,
|
|
w_profils.bul_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.act_code
|
|
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="Pre-traitement de la paie">
|
|
<sqlcmd><![CDATA[
|
|
|
|
DROP TABLE IF EXISTS w_hp
|
|
;
|
|
|
|
CREATE TEMP TABLE w_hp AS
|
|
SELECT
|
|
-- w_hp_0.lb_code,
|
|
w_hp_0.bul_code,
|
|
w_profils.eta_code,
|
|
w_profils.contrat_mois_id,
|
|
w_profils.contrat_id,
|
|
w_profils.salarie_id,
|
|
w_profils.profil_id,
|
|
w_profils.matricule AS matricule,
|
|
w_profils.bul_deb as date_debut,
|
|
w_profils.bul_fin as date_fin,
|
|
w_profils.date_paie,
|
|
w_profils.mois_paie,
|
|
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 w_profils.bul_code = w_hp_0.bul_code
|
|
JOIN rh.t_rubriques ON t_rubriques.code_original = w_hp_0.rub_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)
|
|
;
|
|
|
|
]]></sqlcmd>
|
|
</NODE>
|
|
<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_hp.mois_paie,
|
|
count(DISTINCT matricule),
|
|
sum(montant_brut),
|
|
sum(heure_payee)
|
|
FROM w_hp
|
|
JOIN rh.t_etablissements ON t_etablissements.code_original = w_hp.eta_code
|
|
WHERE true
|
|
and w_hp.mois_paie >= to_char(rhp('rhprovider_start')::date, 'YYYYMM')::int
|
|
and p_cumul
|
|
GROUP BY 1,2,3
|
|
;
|
|
|
|
]]></sqlcmd>
|
|
</NODE>
|
|
<NODE label="Historique de la paie">
|
|
<sqlcmd><![CDATA[
|
|
|
|
-- 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.bul_code 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_paie AS mois_activite,
|
|
w_hp.mois_paie 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.bul_code as code_original,
|
|
w_hp.matricule,
|
|
w_hp.date_paie as date,
|
|
w_hp.mois_paie,
|
|
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
|
|
;
|
|
|
|
-- Insérer pour chaque bulletin une ligne qui va faire le compte avec le total (rubrique 'C000' nommée 'Ecart cumulé')
|
|
with denominateur as (
|
|
select
|
|
w_hp.bul_code as code_original,
|
|
w_hp.matricule,
|
|
w_hp.date_paie,
|
|
w_hp.mois_paie
|
|
from w_hp
|
|
group by 1,2,3,4
|
|
)
|
|
, subq as (
|
|
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
|
|
GROUP BY 1,2,3,4,5,6,7,8,9,10,11, 24,25,26,27
|
|
)
|
|
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_net_a_payer_salarie,
|
|
montant_net_imposable_salarie,
|
|
montant_frais_imposables,
|
|
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) - coalesce(subq.heure_contrat, 0) else 0.0 end AS heure_contrat,
|
|
case when total_h_payees then COALESCE(hcum_heures_payees, 0) - coalesce(subq.heure_payee, 0) else 0.0 end AS heure_payee,
|
|
case when total_h_travaillees then COALESCE(hcum_heures_travaillees, 0) - coalesce(subq.heure_travaillee, 0) else 0.0 end AS heure_travaillee,
|
|
case when total_avantage_nature then COALESCE(hcum_avantage_nature, 0) - coalesce(subq.montant_avantage_nature, 0) else 0.0 end AS montant_avantage_nature,
|
|
case when total_brut then COALESCE(hcum_brut, 0) - coalesce(subq.montant_brut, 0) else 0.0 end AS montant_brut,
|
|
case when total_masse_salariale then COALESCE(hcum_masse_salariale, 0) - coalesce(subq.montant_masse_salariale, 0) else 0.0 end AS montant_masse_salariale,
|
|
case when total_cot_pat then COALESCE(hcum_cotisation_patronale, 0) - coalesce(subq.montant_cotisation_patronale, 0) else 0.0 end AS montant_cotisation_patronale,
|
|
case when total_cot_sal then COALESCE(hcum_cotisation_salarie, 0) - coalesce(subq.montant_cotisation_salarie, 0) else 0.0 end AS montant_cotisation_salarie,
|
|
case when total_payer then COALESCE(hcum_net_a_payer_salarie, 0) - coalesce(subq.montant_net_a_payer_salarie, 0) else 0.0 end AS montant_net_a_payer_salarie,
|
|
case when total_imposable then COALESCE(hcum_net_imposable_salarie, 0) - coalesce(subq.montant_net_imposable_salarie, 0) else 0.0 end AS montant_net_imposable_salarie,
|
|
0 AS montant_frais_imposables,
|
|
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 denominateur
|
|
left join subq on subq.code_original = denominateur.code_original
|
|
left JOIN w_totaux ON w_totaux.code_original = denominateur.code_original
|
|
JOIN w_cumul ON true
|
|
WHERE 1!=1
|
|
OR case when total_h_contrat then COALESCE(hcum_heures_contrat, 0) - coalesce(subq.heure_contrat, 0) != 0 else false end
|
|
OR case when total_h_payees then COALESCE(hcum_heures_payees, 0) - coalesce(subq.heure_payee, 0) != 0 else false end
|
|
OR case when total_h_travaillees then COALESCE(hcum_heures_travaillees, 0) - coalesce(subq.heure_travaillee, 0) != 0 else false end
|
|
OR case when total_avantage_nature then COALESCE(hcum_avantage_nature, 0) - coalesce(subq.montant_avantage_nature, 0) != 0 else false end
|
|
OR case when total_brut then COALESCE(hcum_brut, 0) - coalesce(subq.montant_brut, 0) != 0 else false end
|
|
OR case when total_masse_salariale then COALESCE(hcum_masse_salariale, 0) - coalesce(subq.montant_masse_salariale, 0) != 0 else false end
|
|
OR case when total_cot_pat then COALESCE(hcum_cotisation_patronale, 0) - coalesce(subq.montant_cotisation_patronale, 0) != 0 else false end
|
|
OR case when total_cot_sal then COALESCE(hcum_cotisation_salarie, 0) - coalesce(subq.montant_cotisation_salarie, 0) != 0 else false end
|
|
OR case when total_payer then COALESCE(hcum_net_a_payer_salarie, 0) - coalesce(subq.montant_net_a_payer_salarie, 0) != 0 else false end
|
|
OR case when total_imposable then COALESCE(hcum_net_imposable_salarie, 0) - coalesce(subq.montant_net_imposable_salarie, 0) != 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>
|