Commit cb5b78ad authored by milena rocha's avatar milena rocha

Add new file

parent e7d8ad6e
WITH email_unico AS (
SELECT DISTINCT ON (email)
gu.email,
gu.users_id,
gu.is_default,
gp.profiles_id
FROM glpidb.glpi_useremails gu
JOIN glpidb.glpi_users gp ON gp.id = gu.users_id
ORDER BY gu.email, gu.users_id
),
canais AS (
SELECT
entities_id,
id,
name,
completename
FROM glpi_entities
WHERE name NOT LIKE '%INATIVO%'
),
chamados AS (
SELECT
tu.users_id,
COUNT(DISTINCT t.id) AS chamados
FROM glpidb.glpi_tickets_users tu
JOIN glpidb.glpi_tickets t ON t.id = tu.tickets_id
WHERE tu.type = 1
GROUP BY tu.users_id
),
perfis_agrupados AS (
SELECT
pu.users_id,
STRING_AGG(DISTINCT gp.name, ', ') AS perfis
FROM glpi_profiles_users pu
JOIN glpi_profiles gp ON gp.id = pu.profiles_id
GROUP BY pu.users_id
),
curso AS (
SELECT DISTINCT ON (moodle.mdl_user.email)
moodle.mdl_user.email AS email,
string_agg(moodle.mdl_course.id::TEXT, ', ') AS id_curso,
string_agg(moodle.mdl_course.shortname, ', ') AS nome_curso
FROM moodle.mdl_user_enrolments
LEFT JOIN moodle.mdl_enrol ON moodle.mdl_enrol.id = moodle.mdl_user_enrolments.enrolid
LEFT JOIN moodle.mdl_course ON moodle.mdl_course.id = moodle.mdl_enrol.courseid
LEFT JOIN moodle.mdl_role ON moodle.mdl_role.id = moodle.mdl_enrol.roleid
LEFT JOIN moodle.mdl_user ON moodle.mdl_user.id = moodle.mdl_user_enrolments.userid
GROUP BY moodle.mdl_user.email)
SELECT
eu.users_id,
eu.email,
CASE
WHEN LOWER(SUBSTRING(eu.email FROM '@([^.]*)')) IN ('gmail', 'hotmail', 'outlook','yahoo') THEN UPPER(ap.organizacao)
ELSE UPPER(SUBSTRING(eu.email FROM '@([^.]*)'))
END AS organizacao,
u.locations_id,
gl.latitude,
gl.longitude,
cn.completename AS entidade,
ap.data_criacao,
ap.aplicacao,
COALESCE(curso.nome_curso, 'Sem cursos cadastrados') AS curso,
COALESCE(ap.titulo, 'Profissional') AS publico,
eu.profiles_id,
coalesce(gl.state, 'Não informado') as estado,
coalesce(ap.pesquisa_marketing , 'Não informado')as origem ,
COALESCE(ch.chamados, 0) AS chamados,
CASE
WHEN u.locations_id IN (5, 7, 8, 16, 24, 25, 28) THEN 'Norte'
WHEN u.locations_id IN (6, 9, 10, 12, 17, 19, 20, 22, 27) THEN 'Nordeste'
WHEN u.locations_id IN (1, 2, 13, 14) THEN 'Centro-Oeste'
WHEN u.locations_id IN (11, 15, 3, 4) THEN 'Sudeste'
WHEN u.locations_id IN (18, 23, 26) THEN 'Sul'
WHEN u.locations_id = 29 THEN 'Internacional'
ELSE 'Não Informado'
END AS regiao,
COALESCE(pf.perfis, 'Sem perfil') AS perfis
FROM email_unico eu
LEFT JOIN glpi_users u ON eu.users_id = u.id
LEFT JOIN canais cn ON cn.id = u.entities_id
LEFT JOIN chamados ch ON ch.users_id = eu.users_id
LEFT JOIN perfis_agrupados pf ON pf.users_id = eu.users_id
LEFT JOIN glpi_locations gl ON gl.id = u.locations_id
LEFT JOIN wso2.dados_api ap ON ap.email = eu.email
LEFT JOIN curso ON curso.email = eu.email;
Markdown is supported
0%
or
You are about to add 0 people to the discussion. Proceed with caution.
Finish editing this message first!
Please register or to comment