You can not select more than 25 topics Topics must start with a letter or number, can include dashes ('-') and can be up to 35 characters long.
 
 
 

1269 lines
38 KiB

<?php
set_time_limit(0);
require_once __ROOT__ . '/modules/base/php/lib/Spyc/Spyc.php';
require_once __ROOT__ . '/modules/base/php/lib/PHPExcel/PHPExcel.php';
require_once __ROOT__ . '/modules/base/lib/ICTIDB.class.php';
require_once __ROOT__ . '/modules/base/php/lib/cti/Environnement/Environnement.class.php';
class CtiRhBilanSocialService {
public function isBsEnabled() {
return Environnement::getInstance()->getOptBilanSocial();
}
/**
*
* @return array liste des erreurs à corriger avant de pouvoir générer un BS.
*/
public function diagnose() {
$ret = array();
try {
$con = ICTIDB::getInstance();
$con->beginTransaction();
$sql = "
select *
from (
select case when count(oid) != 2 then 'Pas de classe(s) d''âges et/ou d''anciennetés paramétrée(s) dans Divers.' else null end as error_message
from rh.t_classes
join rh.t_divers on t_divers.valeur = t_classes.code
WHERE 1=1
AND t_divers.code IN ('BS_CLA_AGE', 'BS_CLA_ANC')
UNION
select case when count(oid) = 0 then 'Aucune classe CTI_BS_QUA existante.' else null end as error_message
from rh.t_classes
where code = 'CTI_BS_QUA'
UNION
select case when count(oid) > 1 then 'Plus d''un classe CTI_BS_QUA existante.' else null end as error_message
from rh.t_classes
where code = 'CTI_BS_QUA'
UNION
select case when count(oid) = 1 and max(is_cti) != 0 then 'Classe CTI_BS_QUA ne doit pas être marquée \"CTI\".' else null end as error_message
from rh.t_classes
where code = 'CTI_BS_QUA'
UNION
select
case when count(distinct t_classes.oid) = 1 AND count(distinct t_classes_sections.oid) = 0 then 'Classe CTI_BS_QUA n''a aucune section.' else null end as error_message
from rh.t_classes
left join rh.t_classes_sections on t_classes_sections.classe_id = t_classes.oid
where 1=1
AND t_classes.code = 'CTI_BS_QUA'
AND t_classes.is_cti = 0
UNION
SELECT case when count(distinct t_classes.oid) = 1 then 'Classe CTI_BS_QUA définie sur une mauvaise dimension.' else null end as error_message
FROM rh.t_classes
join rh.t_listes_tables on t_listes_tables.oid = t_classes.table_id
WHERE 1=1
AND t_classes.code = 'CTI_BS_QUA'
AND is_cti = 0
AND t_listes_tables.name NOT IN (
't_qualifications',
't_categories_socio_professionnelles',
't_services',
't_specialites',
't_statuts')
) as error_messages
where error_message is not null
";
foreach ($con->query($sql, PDO::FETCH_ASSOC) as $row) {
$ret[] = $row;
}
$con->commit();
} catch (Exception $e) {
}
return $ret;
}
/**
*
* @return array liste des entreprises/établissements
*/
public function getEntities() {
$ret = array();
try {
$con = ICTIDB::getInstance();
$con->beginTransaction();
$sql = "
SELECT *
FROM (
select
t_entreprises.oid AS ent_id,
0::bigint AS ets_id,
t_entreprises.code_original AS code,
'Ent. '||t_entreprises.code||' - '||t_entreprises.texte AS texte
from rh.t_entreprises
join rh.t_etablissements on t_etablissements.entreprise_id = t_entreprises.oid
join rh.p_contrats ON p_contrats.etablissement_id = t_etablissements.oid
where 1=1
and t_entreprises.oid != 0
UNION
select
t_entreprises.oid AS ent_id,
t_etablissements.oid AS ets_id,
t_etablissements.code_original AS code,
' - Ets. '||t_etablissements.code||' - '||t_etablissements.texte AS texte
from rh.t_entreprises
join rh.t_etablissements on t_etablissements.entreprise_id = t_entreprises.oid
join rh.p_contrats ON p_contrats.etablissement_id = t_etablissements.oid
where 1=1
and t_entreprises.oid != 0
and t_etablissements.oid != 0) AS foo
ORDER BY lpad(code, 6, '0')
";
foreach ($con->query($sql, PDO::FETCH_ASSOC) as $row) {
$ret[] = $row;
}
$con->commit();
} catch (Exception $e) {
}
return $ret;
}
public function fileGenerated($filename) {
$tmpDir = __ROOT__ . '/temp/';
$outputFile = $tmpDir . $filename;
return file_exists($outputFile);
}
public function deleteFile($filename) {
$tmpDir = __ROOT__ . '/temp/';
$outputFile = $tmpDir . $filename;
if (file_exists($outputFile)) {
unlink($outputFile);
}
return true;
}
/**
*
* @param string $annee année à générer
* @param array $entreprise tableau d'entreprises pour lesquelles générer le BS
* @param array $etablissement tableau d'établissements pour lesquels générer le BS
* @return string Description
*/
public function generateExcel($annee, $filename, $entrepriseId = 0, $etablissementId = 0) {
$tmpDiag = $this->diagnose();
if (count($tmpDiag) > 0) {
return "diagnose";
}
$tmpDir = __ROOT__ . '/temp/';
// Test d'existence du dossier 'temp'.
if (!file_exists($tmpDir)) {
mkdir($tmpDir);
}
$outputFile = $tmpDir . $filename;
if (file_exists($outputFile)) {
unlink($outputFile);
}
// Récupération des données de définition du Bilan Social
$fBs = __ROOT__ . '/modules/rh/php/amfphp/services/CtiRhBilanSocialService.yaml';
$data = Spyc::YAMLLoad($fBs);
$conn = ICTIDB::getInstance();
$pgVersion = $conn->getAttribute(PDO::ATTR_SERVER_VERSION);
$isPg9 = (intval(substr($pgVersion, 0, 1)) > 8 ? true : false);
// Les classes d'âges et d'anciennetés sont paramétrées dans la table rh.t_divers.
// Le programme a besoin du n° de séquence pour chacune d'entre elles.
$sequenceAge = 9;
$sequenceAnc = 9;
$sqlDim = "
SELECT
t_listes_tables.name,
t_classes.sequence
from rh.t_classes
join rh.t_listes_tables on t_listes_tables.oid = t_classes.table_id
join rh.t_divers on t_divers.valeur = t_classes.code
WHERE 1=1
AND t_divers.code IN ('BS_CLA_AGE', 'BS_CLA_ANC')
";
$res = $conn->query($sqlDim);
$tmpRes = $res->fetchAll(PDO::FETCH_ASSOC);
foreach ($tmpRes as $tuple) {
switch ($tuple['name']) {
case 't_ages':
$sequenceAge = $tuple['sequence'];
break;
case 't_anciennetes_annee':
$sequenceAnc = $tuple['sequence'];
break;
}
}
// La classe CTI_BS_QUA peut être faite sur n'importe quelle dimension.
$sqlDim = "
SELECT
t_listes_tables.name,
t_classes.sequence
from rh.t_classes
join rh.t_listes_tables on t_listes_tables.oid = t_classes.table_id
WHERE 1=1
AND t_classes.code = 'CTI_BS_QUA'
AND is_cti = 0
LIMIT 1
";
$res = $conn->query($sqlDim);
$tmpRes = $res->fetchAll(PDO::FETCH_ASSOC);
$dimension = "";
$sequence = "";
switch ($tmpRes[0]['name']) {
case 't_qualifications' :
$dimension = "qualification";
break;
case 't_categories_socio_professionnelles' :
$dimension = "categorie_socio_professionnelle";
break;
case 't_services' :
$dimension = "service";
break;
case 't_specialites' :
$dimension = "specialite";
break;
case 't_statuts' :
$dimension = "statut";
break;
default :
$dimension = "statut";
break;
}
$sequence = $tmpRes[0]['sequence'];
// Traitements SQL
$sqlBase = "
drop table if exists w_bs_contrat
;
create temp table w_bs_contrat as
select
" . $dimension . "_section_texte[$sequence] AS cti_bs_qua,
*
from rh.v_contrats_mois_1
where 1=1
AND mois_activite_id between " . $annee . "01 and " . $annee . "12
AND est_hors_periode IS DISTINCT FROM '1'
AND fictif <> '1'
" . ($entrepriseId > 0 ? "AND entreprise_id = $entrepriseId" : "") . "
" . ($etablissementId > 0 ? "AND etablissement_id = $etablissementId" : "") . "
;
DROP TABLE IF EXISTS w_ep
;
CREATE TEMP TABLE w_ep AS
SELECT salarie_id AS efp_salarie_id
FROM w_bs_contrat
WHERE 1=1
AND present_debut_mois = 1
AND present_fin_mois = 1
GROUP BY 1
HAVING count(DISTINCT
CASE WHEN 1=1
AND type_contrat_section_code[9] = 'CDI'
AND type_temps_travail_section_code[9] = 'TC'
THEN mois_activite_id
ELSE null
END) = base.cti_months_between('" . $annee . "0101'::date, '" . $annee . "1231'::date)
;
DROP TABLE IF EXISTS w_bs_contrat_mois
;
CREATE TEMP TABLE w_bs_contrat_mois AS
SELECT
mois_activite_id AS mois,
" . $dimension . "_section_texte[$sequence] AS cti_bs_qua,
count(DISTINCT CASE WHEN present_fin_mois = 1 THEN salarie_id ELSE null END) AS nb_sal_fin_mois
FROM w_bs_contrat
WHERE 1=1
GROUP BY 1,2
;
DROP TABLE IF EXISTS w_bs_arret_mois
;
CREATE TEMP TABLE w_bs_arret_mois AS
SELECT
" . $dimension . "_section_texte[$sequence] AS cti_bs_qua,
*
FROM rh.v_arrets_travail_mois_1
WHERE 1=1
AND mois_activite_id between " . $annee . "01 and " . $annee . "12
" . ($entrepriseId > 0 ? "AND entreprise_id = $entrepriseId" : "") . "
" . ($etablissementId > 0 ? "AND etablissement_id = $etablissementId" : "") . "
;
DROP TABLE IF EXISTS w_bs_arret_mal
;
CREATE TEMP TABLE w_bs_arret_mal AS
SELECT
cti_bs_qua,
arret_travail_id,
sum(nb_jours_arret) AS nb_jours_arret
FROM w_bs_arret_mois
WHERE 1=1
AND motif_arret_section_code[9] = 'MAL'
GROUP BY 1,2
;
DROP TABLE IF EXISTS w_bs_arret_mal_duree
;
CREATE TEMP TABLE w_bs_arret_mal_duree AS
SELECT
cti_bs_qua,
arret_travail_id,
nb_jours_arret,
CASE
WHEN nb_jours_arret BETWEEN 1 AND 3 THEN 'T01|1 à 3 jours'
WHEN nb_jours_arret BETWEEN 4 AND 10 THEN 'T02|4 à 10 jours'
WHEN nb_jours_arret BETWEEN 10 AND 15 THEN 'T03|10 à 15 jours'
WHEN nb_jours_arret BETWEEN 16 AND 30 THEN 'T04|16 à 30 jours'
WHEN nb_jours_arret BETWEEN 31 AND 60 THEN 'T05|1 à 2 mois'
WHEN nb_jours_arret BETWEEN 61 AND 90 THEN 'T06|2 à 3 mois'
WHEN nb_jours_arret BETWEEN 91 AND 120 THEN 'T07|3 à 4 mois'
WHEN nb_jours_arret BETWEEN 121 AND 150 THEN 'T08|4 à 5 mois'
WHEN nb_jours_arret BETWEEN 151 AND 180 THEN 'T09|5 à 6 mois'
WHEN nb_jours_arret BETWEEN 181 AND 212 THEN 'T10|6 à 7 mois'
WHEN nb_jours_arret BETWEEN 213 AND 244 THEN 'T11|7 à 8 mois'
WHEN nb_jours_arret BETWEEN 245 AND 274 THEN 'T12|8 à 9 mois'
WHEN nb_jours_arret BETWEEN 275 AND 304 THEN 'T13|9 à 10 mois'
WHEN nb_jours_arret BETWEEN 305 AND 334 THEN 'T14|10 à 11 mois'
WHEN nb_jours_arret BETWEEN 335 AND 365 THEN 'T15|11 à 12 mois'
ELSE 'T16|+ d''un an'
END AS tranche_duree
FROM w_bs_arret_mal
;
drop table if exists w_bs_paie
;
create temp table w_bs_paie as
select
" . $dimension . "_section_texte[$sequence] AS cti_bs_qua,
mois_activite_id,
salarie_id,
rubrique_id,
montant_masse_salariale,
montant_net_a_payer_salarie
from rh.v_historique_paie_1
where 1=1
AND mois_activite_id between " . $annee . "01 and " . $annee . "12
" . ($entrepriseId > 0 ? "AND entreprise_id = $entrepriseId" : "") . "
" . ($etablissementId > 0 ? "AND etablissement_id = $etablissementId" : "") . "
;
DROP TABLE IF EXISTS w_bs_paie_mois
;
CREATE TEMP TABLE w_bs_paie_mois AS
SELECT
mois,
cti_bs_qua,
sum(nb_cnt_salarie_id) AS nb_cnt_salarie_id,
sum(nb_cnt_sal_fin_mois) AS nb_cnt_sal_fin_mois,
sum(montant_masse_salariale) AS montant_masse_salariale
FROM (
SELECT
mois_activite_id AS mois,
cti_bs_qua,
count(DISTINCT salarie_id) AS nb_cnt_salarie_id,
count(DISTINCT CASE WHEN present_fin_mois = 1 THEN salarie_id ELSE NULL END) AS nb_cnt_sal_fin_mois,
0 AS montant_masse_salariale
FROM w_bs_contrat
GROUP BY 1,2
UNION ALL
SELECT
mois_activite_id,
cti_bs_qua,
0,
0,
sum(montant_masse_salariale)
FROM w_bs_paie
GROUP BY 1,2
) AS subq
GROUP BY 1,2
;
";
if ($isPg9) {
$sqlBase .= "
-- Spécial paie
DROP TABLE IF EXISTS w_bs_paie_special
;
CREATE TEMP TABLE w_bs_paie_special AS
SELECT salarie_id,
foo.cti_bs_qua,
0::BIGINT AS i,
0::BIGINT AS j,
sum(montant_masse_salariale) AS montant_masse_salariale,
0::NUMERIC AS s10m, -- rémunérations représentant 10% des salariés avec les rémunérations les moins élevées
0::NUMERIC AS s10p, -- rémunérations représentant 10% des salariés avec les rémunérations les plus élevées
0::NUMERIC AS m10p -- montant des 10 rémunérations les + élevées
FROM w_bs_paie
JOIN w_ep ON efp_salarie_id = salarie_id
JOIN (
SELECT cti_bs_qua
FROM w_bs_paie
GROUP BY 1
UNION ALL
SELECT 'Total'
) AS foo
ON 1 = 1
WHERE 1!=1
OR foo.cti_bs_qua = 'Total'
OR foo.cti_bs_qua = w_bs_paie.cti_bs_qua
GROUP BY 1,2,3,4,6,7
;
-- Remplir le rang par cti_bs_qua
UPDATE w_bs_paie_special
SET i = ir,
j=jr
FROM (
SELECT
rank() OVER (PARTITION BY cti_bs_qua ORDER BY montant_masse_salariale asc) AS ir,
rank() OVER (PARTITION BY cti_bs_qua ORDER BY montant_masse_salariale desc) AS jr,
*
FROM w_bs_paie_special
) AS foo
WHERE 1 = 1
AND w_bs_paie_special.salarie_id = foo.salarie_id
AND w_bs_paie_special.cti_bs_qua = foo.cti_bs_qua
;
UPDATE w_bs_paie_special
SET s10m = foo1.s10m,
s10p = foo1.s10p,
m10p = foo1.m10p
FROM (
SELECT salarie_id,
i,
w_bs_paie_special.cti_bs_qua,
foo.cti_bs_qua AS ttt,
CASE WHEN (
i::NUMERIC / (
SELECT count(*)::NUMERIC
FROM w_bs_paie_special
WHERE cti_bs_qua = foo.cti_bs_qua
) * 100::NUMERIC
) >= 90 THEN montant_masse_salariale ELSE 0 END AS s10p,
CASE WHEN (
(
(
SELECT count(*)::NUMERIC
FROM w_bs_paie_special
WHERE cti_bs_qua = foo.cti_bs_qua
) - i::NUMERIC + 1
) / (
SELECT count(*)::NUMERIC
FROM w_bs_paie_special
WHERE cti_bs_qua = foo.cti_bs_qua
) * 100::NUMERIC
) >= 90 THEN montant_masse_salariale ELSE 0 END AS s10m,
case when j <= 10 then montant_masse_salariale else 0 end as m10p
FROM w_bs_paie_special
JOIN (
SELECT cti_bs_qua
FROM w_bs_paie
GROUP BY 1
UNION ALL
SELECT 'Total'
) AS foo
ON w_bs_paie_special.cti_bs_qua = foo.cti_bs_qua
GROUP BY 1,2,3,4,5,6,7
ORDER BY 2,4,3
) AS foo1
WHERE 1 = 1
AND w_bs_paie_special.salarie_id = foo1.salarie_id
AND w_bs_paie_special.cti_bs_qua = foo1.cti_bs_qua
;
";
}
$remplacements = array(
'@annee' => $annee,
'@sequenceAge' => $sequenceAge,
'@sequenceAnc' => $sequenceAnc
);
$wBsContratSQL = array(); // requetes sur w_bs_contrat
$wBsContratMoisSQL = array(); // requetes sur w_bs_contrat_mois
$wBsArretMoisSQL = array(); // requetes sur w_bs_arret_mois
$wBsArretMalDureeSQL = array(); // requetes sur w_bs_arret_mal_duree
$wBsPaieSQL = array(); // requetes sur w_bs_paie
$wBsPaieMoisSQL = array(); // requetes sur w_bs_paie_mois
$wBsPaieSpecialSQL = array(); // requetes sur w_bs_paie_special
$currentTempTable = ""; // Table temporaire associée à l'indicateur
// Parcours de tous les indicateurs pour constituer la requête SQL
foreach ($data['bilanSocial2013'] as $niveau1) {
if (key_exists('e', $niveau1)) {
foreach ($niveau1['e'] as $niveau2) {
if (key_exists('e', $niveau2)) {
foreach ($niveau2['e'] as $indicateur) {
$tmpIndicatorName = $niveau1['i'] . '.' . $niveau2['i'] . '.' . $indicateur['i'];
$tmpNull = "null" . ' AS "' . $tmpIndicatorName . '"';
// Recherche de la table de travail pour l'indicateur.
if (key_exists('o', $indicateur)) {
$currentTempTable = $indicateur['o'];
} else if (key_exists('o', $niveau2)) {
$currentTempTable = $niveau2['o'];
} else if (key_exists('o', $niveau1)) {
$currentTempTable = $niveau1['o'];
} else {
// ERREUR : pas de table définie...
}
$wBsContratSQL[] = $tmpNull;
$wBsContratMoisSQL[] = $tmpNull;
$wBsArretMoisSQL[] = $tmpNull;
$wBsArretMalDureeSQL[] = $tmpNull;
$wBsPaieSQL[] = $tmpNull;
$wBsPaieMoisSQL[] = $tmpNull;
$wBsPaieSpecialSQL[] = $tmpNull;
if (key_exists('s', $indicateur)) {
$tmp = strtr($indicateur['s'], $remplacements) . ' AS "' . $tmpIndicatorName . '"';
switch ($currentTempTable) {
case 'w_bs_contrat' :
$wBsContratSQL[] = $tmp;
break;
case 'w_bs_contrat_mois':
$wBsContratMoisSQL[] = $tmp;
break;
case 'w_bs_arret_mois':
$wBsArretMoisSQL[] = $tmp;
break;
case 'w_bs_arret_mal_duree':
$wBsArretMalDureeSQL[] = $tmp;
break;
case 'w_bs_paie':
$wBsPaieSQL[] = $tmp;
break;
case 'w_bs_paie_mois':
$wBsPaieMoisSQL[] = $tmp;
break;
case 'w_bs_paie_special':
$wBsPaieSpecialSQL[] = $tmp;
break;
}
}
// Dans le cas d'indicateurs enfants.
if (key_exists('e', $indicateur)) {
foreach ($indicateur['e'] as $indicateurEnfant) {
if (key_exists('s', $indicateurEnfant)) {
$tmpIndicatorName = $niveau1['i'] . '.' . $niveau2['i'] . '.' . $indicateur['i'].'.'.$indicateurEnfant['i'];
$tmpNull = "null" . ' AS "' . $tmpIndicatorName . '"';
// La table de travail est actuellement celle de l'indicateur parent par défaut.
$tmp = strtr($indicateurEnfant['s'], $remplacements) . ' AS "' . $tmpIndicatorName . '"';
$wBsContratSQL[] = $tmpNull;
$wBsContratMoisSQL[] = $tmpNull;
$wBsArretMoisSQL[] = $tmpNull;
$wBsArretMalDureeSQL[] = $tmpNull;
$wBsPaieSQL[] = $tmpNull;
$wBsPaieMoisSQL[] = $tmpNull;
$wBsPaieSpecialSQL[] = $tmpNull;
switch ($currentTempTable) {
case 'w_bs_contrat' :
$wBsContratSQL[] = $tmp;
break;
case 'w_bs_contrat_mois':
$wBsContratMoisSQL[] = $tmp;
break;
case 'w_bs_arret_mois':
$wBsArretMoisSQL[] = $tmp;
break;
case 'w_bs_arret_mal_duree':
$wBsArretMalDureeSQL[] = $tmp;
break;
case 'w_bs_paie':
$wBsPaieSQL[] = $tmp;
break;
case 'w_bs_paie_mois':
$wBsPaieMoisSQL[] = $tmp;
break;
case 'w_bs_paie_special':
$wBsPaieSpecialSQL[] = $tmp;
break;
}
}
}
}
}
}
}
}
}
// Exécution de la requête
$sqlCmd = $sqlBase . PHP_EOL;
// Contrats
$sqlCmd .= "
SELECT
1 AS level,
cti_bs_qua,";
$sqlCmd .= implode(',', $wBsContratSQL);
$sqlCmd .= PHP_EOL . "from w_bs_contrat
left join w_ep on w_ep.efp_salarie_id = w_bs_contrat.salarie_id
where 1=1
group by 1,2
UNION ALL
select
0,
'Total'::text,
";
$sqlCmd .= implode(',', $wBsContratSQL);
$sqlCmd .= PHP_EOL . "from w_bs_contrat
left join w_ep on w_ep.efp_salarie_id = w_bs_contrat.salarie_id
where 1=1
group by 1,2
ORDER BY 1 DESC, 2
";
// Contrats mois
$monthlySqlCmd = "
SELECT
1 AS level,
cti_bs_qua,";
$monthlySqlCmd .= implode(',', $wBsContratMoisSQL);
$monthlySqlCmd .= PHP_EOL . "from w_bs_contrat_mois
where 1=1
group by 1,2
UNION ALL
select
0,
'Total'::text,
";
$monthlySqlCmd .= implode(',', $wBsContratMoisSQL);
$monthlySqlCmd .= PHP_EOL . "from w_bs_contrat_mois
where 1=1
group by 1,2
ORDER BY 1 DESC, 2
";
// Arrets
$arretSqlCmd = "
SELECT
1 AS level,
cti_bs_qua,";
$arretSqlCmd .= implode(',', $wBsArretMoisSQL);
$arretSqlCmd .= PHP_EOL . "from w_bs_arret_mois
where 1=1
group by 1,2
UNION ALL
select
0,
'Total'::text,
";
$arretSqlCmd .= implode(',', $wBsArretMoisSQL);
$arretSqlCmd .= PHP_EOL . "from w_bs_arret_mois
where 1=1
group by 1,2
ORDER BY 1 DESC, 2
";
// Arrets Maladie Durée
$arretMalDureeSqlCmd = "
SELECT
1 AS level,
cti_bs_qua,";
$arretMalDureeSqlCmd .= implode(',', $wBsArretMalDureeSQL);
$arretMalDureeSqlCmd .= PHP_EOL . "from w_bs_arret_mal_duree
where 1=1
group by 1,2
UNION ALL
select
0,
'Total'::text,
";
$arretMalDureeSqlCmd .= implode(',', $wBsArretMalDureeSQL);
$arretMalDureeSqlCmd .= PHP_EOL . "from w_bs_arret_mal_duree
where 1=1
group by 1,2
ORDER BY 1 DESC, 2
";
// Paies
$paieSqlCmd = "
SELECT
1 AS level,
cti_bs_qua,";
$paieSqlCmd .= implode(',', $wBsPaieSQL);
$paieSqlCmd .= PHP_EOL . "from w_bs_paie
left join w_ep on w_ep.efp_salarie_id = w_bs_paie.salarie_id
where 1=1
group by 1,2
UNION ALL
select
0,
'Total'::text,
";
$paieSqlCmd .= implode(',', $wBsPaieSQL);
$paieSqlCmd .= PHP_EOL . "from w_bs_paie
left join w_ep on w_ep.efp_salarie_id = w_bs_paie.salarie_id
where 1=1
group by 1,2
ORDER BY 1 DESC, 2
";
// Paies Mois
$paieMoisSqlCmd = "
SELECT
1 AS level,
cti_bs_qua,";
$paieMoisSqlCmd .= implode(',', $wBsPaieMoisSQL);
$paieMoisSqlCmd .= PHP_EOL . "from w_bs_paie_mois
where 1=1
group by 1,2
UNION ALL
select
0,
'Total'::text,
";
$paieMoisSqlCmd .= implode(',', $wBsPaieMoisSQL);
$paieMoisSqlCmd .= PHP_EOL . "from w_bs_paie_mois
where 1=1
group by 1,2
ORDER BY 1 DESC, 2
";
if ($isPg9) {
// Paies Special
$paieSpecialSqlCmd = "
SELECT
1 AS level,
cti_bs_qua,";
$paieSpecialSqlCmd .= implode(',', $wBsPaieSpecialSQL);
$paieSpecialSqlCmd .= PHP_EOL . "from w_bs_paie_special
where 1=1
group by 1,2
UNION ALL
select
0,
'Total'::text,
";
$paieSpecialSqlCmd .= implode(',', $wBsPaieSpecialSQL);
$paieSpecialSqlCmd .= PHP_EOL . "from w_bs_paie_special
where 1=1
group by 1,2
ORDER BY 1 DESC, 2
";
}
// Traitement des résultat Contrat
$res = $conn->query($sqlCmd);
$tmpRes = $res->fetchAll(PDO::FETCH_ASSOC);
$nbDataCol = count($tmpRes);
$iDataRes = array();
foreach ($tmpRes as $value) {
foreach ($value as $key1 => $value1) {
if ($key1 != 'level' || $key1 != 'cti_bs_qua') {
$iDataRes[$key1][$value['cti_bs_qua']] = $value1;
}
}
}
// Traitement des résultat Contrats mois
$res = $conn->query($monthlySqlCmd);
$tmpRes = $res->fetchAll(PDO::FETCH_ASSOC);
foreach ($tmpRes as $value) {
foreach ($value as $key1 => $value1) {
if ($key1 != 'level' || $key1 != 'cti_bs_qua') {
if (!isset($iDataRes[$key1][$value['cti_bs_qua']])) {
$iDataRes[$key1][$value['cti_bs_qua']] = $value1;
}
}
}
}
// Traitement des résultat Arrets.
$res = $conn->query($arretSqlCmd);
$tmpRes = $res->fetchAll(PDO::FETCH_ASSOC);
foreach ($tmpRes as $value) {
foreach ($value as $key1 => $value1) {
if ($key1 != 'level' || $key1 != 'cti_bs_qua') {
if (!isset($iDataRes[$key1][$value['cti_bs_qua']])) {
$iDataRes[$key1][$value['cti_bs_qua']] = $value1;
}
}
}
}
// Traitement des résultat Arrets maladie durée.
$res = $conn->query($arretMalDureeSqlCmd);
$tmpRes = $res->fetchAll(PDO::FETCH_ASSOC);
foreach ($tmpRes as $value) {
foreach ($value as $key1 => $value1) {
if ($key1 != 'level' || $key1 != 'cti_bs_qua') {
if (!isset($iDataRes[$key1][$value['cti_bs_qua']])) {
$iDataRes[$key1][$value['cti_bs_qua']] = $value1;
}
}
}
}
// Traitement des résultat Paies.
$res = $conn->query($paieSqlCmd);
$tmpRes = $res->fetchAll(PDO::FETCH_ASSOC);
foreach ($tmpRes as $value) {
foreach ($value as $key1 => $value1) {
if ($key1 != 'level' || $key1 != 'cti_bs_qua') {
if (!isset($iDataRes[$key1][$value['cti_bs_qua']])) {
$iDataRes[$key1][$value['cti_bs_qua']] = $value1;
}
}
}
}
// Traitement des résultat Paies Mois.
$res = $conn->query($paieMoisSqlCmd);
$tmpRes = $res->fetchAll(PDO::FETCH_ASSOC);
foreach ($tmpRes as $value) {
foreach ($value as $key1 => $value1) {
if ($key1 != 'level' || $key1 != 'cti_bs_qua') {
if (!isset($iDataRes[$key1][$value['cti_bs_qua']])) {
$iDataRes[$key1][$value['cti_bs_qua']] = $value1;
}
}
}
}
// Traitement des résultat Paies Spéciales.
if ($isPg9) {
$res = $conn->query($paieSpecialSqlCmd);
$tmpRes = $res->fetchAll(PDO::FETCH_ASSOC);
foreach ($tmpRes as $value) {
foreach ($value as $key1 => $value1) {
if ($key1 != 'level' || $key1 != 'cti_bs_qua') {
if (!isset($iDataRes[$key1][$value['cti_bs_qua']])) {
$iDataRes[$key1][$value['cti_bs_qua']] = $value1;
}
}
}
}
}
// Génération du fichier Excel
$objPHPExcel = new PHPExcel();
$objPHPExcel->getProperties()->setCreator("CTI Santé");
$objPHPExcel->getProperties()->setLastModifiedBy("CTI Santé");
$objPHPExcel->getProperties()->setTitle("Bilan social $annee");
$objPHPExcel->getProperties()->setSubject("Bilan social $annee");
$objPHPExcel->getProperties()->setDescription("Bilan social $annee - CTI Santé");
$objPHPExcel->removeSheetByIndex(); // Suppression feuille par défaut "Worksheet"
$sheetIndex = 0;
$gras = array(
'font' => array(
'size' => 12,
'bold' => true,
'color' => array(
'rgb' => 'FFFFFF'
)
)
);
$gras2 = array(
'font' => array(
'bold' => true
)
);
$fill = array(
'type' => PHPExcel_Style_Fill::FILL_SOLID,
'color' => array('rgb' => '012b43')
)
;
$dataOddFill = array(
'type' => PHPExcel_Style_Fill::FILL_SOLID,
'color' => array('rgb' => 'EEEEEE')
)
;
$totalOddFill = array(
'type' => PHPExcel_Style_Fill::FILL_SOLID,
'color' => array('rgb' => 'CCCCCC')
)
;
$totalEvenFill = array(
'type' => PHPExcel_Style_Fill::FILL_SOLID,
'color' => array('rgb' => 'EEEEEE')
)
;
$NRFont = array(
'font' => array(
'color' => array(
'rgb' => 'FF552A'
)
)
);
$alignmentVC = array(
'vertical' => PHPExcel_Style_Alignment::VERTICAL_CENTER
);
$alignmentHCVC = array(
'horizontal' => PHPExcel_Style_Alignment::HORIZONTAL_CENTER,
'vertical' => PHPExcel_Style_Alignment::VERTICAL_CENTER
);
$alignmentHCW = array(
'horizontal' => PHPExcel_Style_Alignment::HORIZONTAL_CENTER,
'wrap' => true
);
$alignmentW = array('wrap' => true);
$alignmentVT = array('vertical' => PHPExcel_Style_Alignment::VERTICAL_TOP);
foreach ($data['bilanSocial2013'] as $niveau1) {
//echo PHP_EOL . $niveau1['t'];
$sheetName = utf8_encode($niveau1['i'] . '. ' . $niveau1['t']);
$objPHPExcel->createSheet($sheetIndex);
$objPHPExcel->setActiveSheetIndex($sheetIndex);
$sheet = $objPHPExcel->getActiveSheet();
$sheet->getPageSetup()->setPaperSize(PHPExcel_Worksheet_PageSetup::PAPERSIZE_A4);
$sheet->getPageSetup()->setOrientation(PHPExcel_Worksheet_PageSetup::ORIENTATION_LANDSCAPE);
//$sheet->getPageSetup()->setScale(20);
$sheet->getPageSetup()->setFitToPage(true);
$sheet->getPageSetup()->setFitToWidth(1);
$sheet->getPageSetup()->setFitToHeight(0);
$sheet->getPageSetup()->setHorizontalCentered(true);
$sheet->getPageSetup()->setVerticalCentered(true);
//$sheet->getHeaderFooter()->setOddHeader('&A');
$sheet->getHeaderFooter()->setOddHeader("Bilan Social $annee " . html_entity_decode("&#8226; ", ENT_COMPAT | ENT_HTML401, 'UTF-8') . ' ' . utf8_encode($niveau1['i'] . '. ' . $niveau1['xt']));
$sheet->getHeaderFooter()->setOddFooter('Page &P de &N');
//$sheet->getHeaderFooter()->setEvenFooter('Page &P de &N');
$sheet->setTitle($sheetName);
$sheet->getColumnDimensionByColumn(0)->setWidth(5);
$sheet->getColumnDimensionByColumn(1)->setWidth(50);
for ($i = 2; $i <= (count($iDataRes["cti_bs_qua"]) + 1); $i++) {
$sheet->getColumnDimensionByColumn($i)->setWidth(15);
}
$c = 1;
$r = 1;
if (key_exists('e', $niveau1)) {
foreach ($niveau1['e'] as $niveau2) {
$sheet->setCellValueExplicit($this->cvt(1, $r), utf8_encode($niveau1['i'] . '.' . $niveau2['i']), PHPExcel_Cell_DataType::TYPE_STRING);
$sheet->setCellValueExplicit($this->cvt(2, $r), utf8_encode($niveau2['t']), PHPExcel_Cell_DataType::TYPE_STRING);
$sheet->getStyle($this->cvt(1, $r, $nbDataCol + 2, $r))->getAlignment()->applyFromArray($alignmentVC);
$sheet->getStyle($this->cvt(3, $r, $nbDataCol + 2, $r))->getAlignment()->applyFromArray($alignmentHCW);
$sheet->getStyle($this->cvt(1, $r, $nbDataCol + 2, $r))->applyFromArray($gras);
$sheet->getStyle($this->cvt(1, $r, $nbDataCol + 2, $r))->getFill()->applyFromArray($fill);
if (key_exists('c', $niveau2)) {
$sheet->getComment($this->cvt(2, $r))->getText()->createTextRun(utf8_encode($niveau2['c']));
}
// Ecriture de l'entête de tableau
$i = 2;
foreach ($iDataRes["cti_bs_qua"] as $value) {
$sheet->setCellValueExplicitByColumnAndRow($i, $r, utf8_encode($value), PHPExcel_Cell_DataType::TYPE_STRING);
$i++;
}
$sheet->getRowDimension($r)->setRowHeight(30);
$r++;
if (key_exists('e', $niveau2)) {
foreach ($niveau2['e'] as $indicateur) {
$indicateurNom = $niveau1['i'] . '.' . $niveau2['i'] . '.' . $indicateur['i'];
$sheet->setCellValueExplicitByColumnAndRow(0, $r, utf8_encode($indicateurNom), PHPExcel_Cell_DataType::TYPE_STRING);
$sheet->setCellValueExplicitByColumnAndRow(1, $r, utf8_encode($indicateur['t']), PHPExcel_Cell_DataType::TYPE_STRING);
if ($this->is_odd($r)) {
$sheet->getStyle($this->cvt(1, $r, $nbDataCol + 1, $r))->getFill()->applyFromArray($dataOddFill);
$sheet->getStyleByColumnAndRow($nbDataCol + 1, $r)->getFill()->applyFromArray($totalOddFill);
$sheet->getStyle($this->cvt(1, $r, 2, $r))->getFill()->applyFromArray($totalOddFill);
} else {
$sheet->getStyleByColumnAndRow($nbDataCol + 1, $r)->getFill()->applyFromArray($totalEvenFill);
$sheet->getStyle($this->cvt(1, $r, 2, $r))->getFill()->applyFromArray($totalEvenFill);
}
$sheet->getStyleByColumnAndRow($nbDataCol + 1, $r)->applyFromArray($gras2);
if (key_exists('c', $indicateur)) {
$sheet->getCommentByColumnAndRow(1, $r)->getText()->createTextRun(utf8_encode($indicateur['c']));
}
// Rechercher le format du nombre à appliquer.
if (key_exists('f', $indicateur)) {
$format = html_entity_decode(utf8_encode($indicateur['f']), ENT_COMPAT | ENT_HTML401, 'UTF-8');
} else if (key_exists('f', $niveau2)) {
$format = html_entity_decode(utf8_encode($niveau2['f']), ENT_COMPAT | ENT_HTML401, 'UTF-8');
} else if (key_exists('f', $niveau1)) {
$format = html_entity_decode(utf8_encode($niveau1['f']), ENT_COMPAT | ENT_HTML401, 'UTF-8');
} else {
// ERREUR : pas de format défini...
}
// Détecter si plusieurs sous niveau
$subLevelType = 0;
// Traitement des valeurs encapsulées dans {}
if (substr($iDataRes[$indicateurNom]['Total'], 0, 2) == '{{') {
$subLevelType = 1;
}
// Traitements des enfants non numérotés
if (key_exists('e', $indicateur)) {
$subLevelType = 2;
}
// Si indicateur standard (sans sous-niveau) ou
// si indicateur avec enfants (définis à la main avec noeud de type e:) et avec une définition SQL,
// alors on inscrit le résultat, sinon rien.
if ($subLevelType === 0 || ($subLevelType === 2 && key_exists('s', $indicateur))) {
$sheet->getStyleByColumnAndRow(0, $r)->getAlignment()->applyFromArray($alignmentVT);
$sheet->getStyleByColumnAndRow(1, $r)->getAlignment()->applyFromArray($alignmentW);
$rowNR = true;
$i = 2;
foreach ($iDataRes[$indicateurNom] as $header => $value) {
$sheet->setCellValueExplicitByColumnAndRow($i, $r, utf8_encode($value), PHPExcel_Cell_DataType::TYPE_NUMERIC);
if (isset($value)) {
$rowNR = false;
}
$i++;
}
$sheet->getStyle($this->cvt(3, $r, $nbDataCol + 2, $r))->getAlignment()->applyFromArray($alignmentHCVC);
if ($rowNR) {
$sheet->getStyle($this->cvt(3, $r, $nbDataCol + 2, $r))->applyFromArray($NRFont);
} else {
$sheet->getStyle($this->cvt(3, $r, $nbDataCol + 2, $r))->getNumberFormat()->setFormatCode($format);
}
}
// Traitement des sous-niveaux.
switch ($subLevelType) {
case 1:
$tmpDba = array();
foreach ($iDataRes[$indicateurNom] as $header => $value2) {
$tmpVal = preg_split("/({{|},{|}})/", $value2, -1, PREG_SPLIT_NO_EMPTY);
foreach ($tmpVal as $value4) {
$tmpSubLevelValue = explode(',', $value4);
$tmpDba[$tmpSubLevelValue[0]][$header] = $tmpSubLevelValue[1];
}
}
if (key_exists('sort', $indicateur)) {
if ($indicateur['sort'] == "asc") {
uksort($tmpDba, array($this, "classeSectionCompareAsc"));
} else {
uksort($tmpDba, array($this, "classeSectionCompareDesc"));
}
}
foreach ($tmpDba as $cHeader => $value3) {
$tmp = explode('|', $cHeader);
$header = trim($tmp[1], "\"");
$r++;
$sheet->setCellValueExplicitByColumnAndRow(1, $r, html_entity_decode("&#8226; ", ENT_COMPAT | ENT_HTML401, 'UTF-8') . utf8_encode($header), PHPExcel_Cell_DataType::TYPE_STRING);
$sheet->getStyleByColumnAndRow(0, $r)->getAlignment()->applyFromArray($alignmentVT);
$sheet->getStyleByColumnAndRow(1, $r)->getAlignment()->applyFromArray($alignmentW);
if ($this->is_odd($r)) {
$sheet->getStyle($this->cvt(1, $r, $nbDataCol + 1, $r))->getFill()->applyFromArray($dataOddFill);
$sheet->getStyleByColumnAndRow($nbDataCol + 1, $r)->getFill()->applyFromArray($totalOddFill);
$sheet->getStyle($this->cvt(1, $r, 2, $r))->getFill()->applyFromArray($totalOddFill);
} else {
$sheet->getStyleByColumnAndRow($nbDataCol + 1, $r)->getFill()->applyFromArray($totalEvenFill);
$sheet->getStyle($this->cvt(1, $r, 2, $r))->getFill()->applyFromArray($totalEvenFill);
}
$sheet->getStyleByColumnAndRow($nbDataCol + 1, $r)->applyFromArray($gras2);
$rowNR = true;
$i = 2;
foreach ($iDataRes[$indicateurNom] as $header => $value) {
$sheet->setCellValueExplicitByColumnAndRow($i, $r, utf8_encode($value3[$header]), PHPExcel_Cell_DataType::TYPE_NUMERIC);
if (isset($value3[$header])) {
$rowNR = false;
}
$i++;
}
$sheet->getStyle($this->cvt(3, $r, $nbDataCol + 2, $r))->getAlignment()->applyFromArray($alignmentHCVC);
if ($rowNR) {
$sheet->getStyle($this->cvt(3, $r, $nbDataCol + 2, $r))->applyFromArray($NRFont);
} else {
$sheet->getStyle($this->cvt(3, $r, $nbDataCol + 2, $r))->getNumberFormat()->setFormatCode($format);
}
}
break;
case 2:
foreach ($indicateur['e'] as $subChild) {
$r++;
$sheet->setCellValueExplicitByColumnAndRow(1, $r, html_entity_decode("&#8226; ", ENT_COMPAT | ENT_HTML401, 'UTF-8') . utf8_encode($subChild['t']), PHPExcel_Cell_DataType::TYPE_STRING);
$sheet->getStyleByColumnAndRow(0, $r)->getAlignment()->applyFromArray($alignmentVT);
$sheet->getStyleByColumnAndRow(1, $r)->getAlignment()->applyFromArray($alignmentW);
if ($this->is_odd($r)) {
$sheet->getStyle($this->cvt(1, $r, $nbDataCol + 1, $r))->getFill()->applyFromArray($dataOddFill);
$sheet->getStyleByColumnAndRow($nbDataCol + 1, $r)->getFill()->applyFromArray($totalOddFill);
$sheet->getStyle($this->cvt(1, $r, 2, $r))->getFill()->applyFromArray($totalOddFill);
} else {
$sheet->getStyleByColumnAndRow($nbDataCol + 1, $r)->getFill()->applyFromArray($totalEvenFill);
$sheet->getStyle($this->cvt(1, $r, 2, $r))->getFill()->applyFromArray($totalEvenFill);
}
$sheet->getStyleByColumnAndRow($nbDataCol + 1, $r)->applyFromArray($gras2);
// clef "c" : commentaire de cellule.
if (key_exists('c', $subChild)) {
$sheet->getCommentByColumnAndRow(1, $r)->getText()->createTextRun(utf8_encode($subChild['c']));
}
// clef "v" : visibilité de ligne.
if (key_exists('v', $subChild)) {
$sheet->getRowDimension($r)->setVisible($subChild['v'] === 'true');
}
$rowNR = true;
$i = 2;
foreach ($iDataRes[$indicateurNom.'.'.$subChild['i']] as $header => $value) {
$sheet->setCellValueExplicitByColumnAndRow($i, $r, utf8_encode($value), PHPExcel_Cell_DataType::TYPE_NUMERIC);
if (isset($value)) {
$rowNR = false;
}
$i++;
}
$subChildFormat = $format;
if (key_exists('f', $subChild)) {
$subChildFormat = html_entity_decode(utf8_encode($subChild['f']), ENT_COMPAT | ENT_HTML401, 'UTF-8');
}
$sheet->getStyle($this->cvt(3, $r, $nbDataCol + 2, $r))->getAlignment()->applyFromArray($alignmentHCVC);
if ($rowNR) {
$sheet->getStyle($this->cvt(3, $r, $nbDataCol + 2, $r))->applyFromArray($NRFont);
} else {
$sheet->getStyle($this->cvt(3, $r, $nbDataCol + 2, $r))->getNumberFormat()->setFormatCode($subChildFormat);
}
}
break;
default:
// Pas de comportement par défaut.
break;
}
$r++;
}
}
}
}
$sheetIndex++;
}
$objWriter = PHPExcel_IOFactory::createWriter($objPHPExcel, 'Excel2007');
//$objWriter = new PHPExcel_Writer_Excel2007($objPHPExcel);
$objWriter->save($outputFile);
return $outputFile;
}
private function cvt($c, $r, $c1 = null, $r1 = null) {
if ($c1 == null) {
return PHPExcel_Calculation_LookupRef::CELL_ADDRESS($r, $c, 4);
} else {
return PHPExcel_Calculation_LookupRef::CELL_ADDRESS($r, $c, 4) . ':' . PHPExcel_Calculation_LookupRef::CELL_ADDRESS($r1, $c1, 4);
}
}
private function is_odd($n) {
return (boolean) ($n % 2);
}
public function classeSectionCompareAsc($s1, $s2) {
return $this->classeSectionCompare($s1, $s2, "asc");
}
public function classeSectionCompareDesc($s1, $s2) {
return $this->classeSectionCompare($s1, $s2, "desc");
}
private function classeSectionCompare($s1, $s2, $dir = "asc") {
$tmp1 = explode('|', $s1);
$a = trim($tmp1[0], "\"");
$tmp2 = explode('|', $s2);
$b = trim($tmp2[0], "\"");
if ($a == $b) {
$r = 0;
} else {
if ($dir == "asc") {
$r = ($a > $b) ? 1 : -1;
} else {
$r = ($b > $a) ? 1 : -1;
}
}
return $r;
}
}