Commit c69d7ffb authored by Milena Linda's avatar Milena Linda

feta:readme

parent dfecc425
# Downloads do Nexus # Downloads do Nexus – PGSYS & TDP
Este repositório tem como objetivo centralizar as consultas e documentações referentes aos **downloads realizados pelos usuários** no [Nexus Repository da Tecnisys](https://repo.tecnisys.com.br/).
---
## Objetivo
* A partir da base de dados **Superset**, no schema `nexus` e na tabela `downloads`, iremos identificar os eventos de download realizados por usuários.
* Com base nesses eventos, iremos popular as tabelas `downloads_postgresys` e `downloads_tdp` do banco de dados `superset`, dentro do schema `superset_consolidado`.
* Definir critérios claros do que será considerado **download completo** para cada plataforma.
---
## Critérios de Download Completo
### Para o **PGSYS**
Será considerado **download completo** quando o usuário realizar o download de todos os artefatos obrigatórios da plataforma **PGSYS**, que incluem (dependendo da versão):
* **Versões 2.2.2 a 2.2.3**
* `pgsmart.rpm`
* **Versões 2.3.0 a 2.3.4**
* `pgsmart.rpm`
* **Versões 3.0.0 a 3.1.1**
* `pgsmart-agent.rpm`
* `pgsmart-client.rpm`
* **Versões 4.0.0**
* `pgsmart-agent.rpm`
* `pgsmart-client.rpm`
* `pgsmart-web.rpm`
### Para o **TDP**
Será considerado **download completo** quando o usuário realizar o download de todos os componentes essenciais da **Tecnisys Data Platform**, que incluem (dependendo da versão):
* **Versões 2.2.2 a 2.3.0**
* `tdp-core`
* `tdp-ingestion`
* `tdp-processing`
* `tdp-analytics`
* Pacotes auxiliares/documentação
---
## Estrutura do Repositório
```
.
├── README.md # Documentação principal
└── consultas/ # Scripts e consultas para checar os downloads
├── [consulta_antiga.md](./consultas/consulta_antiga.sql) # Primeira consulta feita por Felipe e Talles
└── [consultas_1.0.md](./consultas/consulta_1.0.md) # Refatorada por Milena
```
---
| Versão | Data | Autor | Alterações |
| ------ | ---------- | ---------------- | ------------------------------------------------------------------------------------------------------- |
| 1.0 | 09/09/2025 | Milena Rcoha | Criação inicial do repositório e definição dos critérios de download completo para **PGSYS** e **TDP**. |
with agent as (
select
(
case
when downloads.email = 'admin'
or downloads.email like 'admin/%' then 'registro@tecnisys.com.br'
when position('/' in downloads.email) > 0 then SUBSTRING(
downloads.email
from
1 for position('/' in downloads.email) - 1
)
else ue.email
end
) as email_a,
SPLIT_PART(downloads.email,
'/',
2) as ip_a,
case
when downloads.email = 'admin'
and users_id is null
or downloads.email like 'admin/%'
and users_id is null then 1
else ue.users_id
end as users_id_a,
case
when regexp_replace(downloads.context,
'.*/([^/]+)/[^/]+$',
'\1') = 'pgsmart' then regexp_replace(
downloads.context,
'.*/([^/]+)/[^/]+/[^/]+$',
'\1'
)
else regexp_replace(downloads.context,
'.*/([^/]+)/[^/]+$',
'\1')
end as sistema_operacional_a,
context as context_a,
timestamp::TIMESTAMP as data_a,
case
when SUBSTRING (
context
from
'([0-9]+.[0-9]+.[0-9]+)'
) is null
and context like '%/latest%'
or context = '/pgsys' then (
case
when DATE_TRUNC ('day',
downloads.timestamp)::DATE between '2022-01-01' and '2022-03-31' then '1.2.0'
when DATE_TRUNC ('day',
downloads.timestamp)::DATE between '2022-04-01' and '2022-06-30' then '2.0.0'
when DATE_TRUNC ('day',
downloads.timestamp)::DATE between '2022-07-01' and '2022-09-30' then '2.1.0'
when DATE_TRUNC ('day',
downloads.timestamp)::DATE between '2022-10-01' and '2022-12-31' then '2.2.0'
when DATE_TRUNC ('day',
downloads.timestamp)::DATE between '2023-01-01' and '2023-06-30' then '2.2.0'
when DATE_TRUNC ('day',
downloads.timestamp)::DATE between '2023-07-01' and '2023-12-31' then '2.3.0'
when DATE_TRUNC ('day',
downloads.timestamp)::DATE between '2024-01-01' and '2024-06-30' then '3.0.0'
when DATE_TRUNC ('day',
downloads.timestamp)::DATE between '2024-07-01' and '2024-12-31' then '3.1.0'
when DATE_TRUNC ('day',
downloads.timestamp)::DATE between '2025-01-01' and '2025-06-30' then '4.0.0'
when DATE_TRUNC ('day',
downloads.timestamp)::DATE between '2025-07-01' and '2025-12-31' then '4.1.0'
when DATE_TRUNC ('day',
downloads.timestamp)::DATE between '2026-01-01' and '2025-06-30' then '5.0.0'
when DATE_TRUNC ('day',
downloads.timestamp)::DATE between '2026-07-01' and '2026-12-31' then '5.1.0'
else 'Não Informado (latest)'
end
)
else replace (
SUBSTRING (
context
from
'([0-9]+.[0-9]+.[0-9]+)'
),
'-',
'.'
)
end as versao_pgsys_a,
case
when context like '/pgsys%/pgsmart%pgsmart-agent%' then 'agent'
when context like '/pgsys%/pgsmart%pgsmart-client%' then 'client'
end as arquivo_a,
row_number() over (
partition by (
case
when downloads.email = 'admin'
or downloads.email like 'admin/%' then 'registro@tecnisys.com.br'
when position('/' in downloads.email) > 0 then SUBSTRING(
downloads.email
from
1 for position('/' in downloads.email) - 1
)
else ue.email
end
),
SUBSTRING (
context
from
'([0-9]+.[0-9]+.[0-9]+)-'
),
(
case
when regexp_replace(downloads.context,
'.*/([^/]+)/[^/]+$',
'\1') = 'pgsmart' then regexp_replace(
downloads.context,
'.*/([^/]+)/[^/]+/[^/]+$',
'\1'
)
else regexp_replace(downloads.context,
'.*/([^/]+)/[^/]+$',
'\1')
end
)
order by
timestamp
) as rn_a
from
nexus.downloads
left join (
select
distinct on
(email,
users_id) email,
MIN(users_id) as users_id
from
glpidb.glpi_useremails
group by
email
) ue on
ue.email = (
case
when downloads.email = 'admin'
or downloads.email like 'admin/%' then 'registro@tecnisys.com.br'
when position('/' in downloads.email) > 0 then SUBSTRING(
downloads.email
from
1 for position('/' in downloads.email) - 1
)
else downloads.email
end
)
where
context like '/pgsys%/pgsmart%pgsmart-agent%'
order by
timestamp desc
),
client as (
select
(
case
when downloads.email = 'admin'
or downloads.email like 'admin/%' then 'registro@tecnisys.com.br'
when position('/' in downloads.email) > 0 then SUBSTRING(
downloads.email
from
1 for position('/' in downloads.email) - 1
)
else ue.email
end
) as email_c,
SPLIT_PART(downloads.email,
'/',
2) as ip_c,
case
when downloads.email = 'admin'
and users_id is null
or downloads.email like 'admin/%'
and users_id is null then 1
else ue.users_id
end as users_id_c,
case
when regexp_replace(downloads.context,
'.*/([^/]+)/[^/]+$',
'\1') = 'pgsmart' then regexp_replace(
downloads.context,
'.*/([^/]+)/[^/]+/[^/]+$',
'\1'
)
else regexp_replace(downloads.context,
'.*/([^/]+)/[^/]+$',
'\1')
end as sistema_operacional_c,
context as context_c,
timestamp as data_c,
case
when SUBSTRING (
context
from
'([0-9]+.[0-9]+.[0-9]+)'
) is null
and context like '%/latest%'
or context = '/pgsys' then (
case
when DATE_TRUNC ('day',
downloads.timestamp)::DATE between '2022-01-01' and '2022-03-31' then '1.2.0'
when DATE_TRUNC ('day',
downloads.timestamp)::DATE between '2022-04-01' and '2022-06-30' then '2.0.0'
when DATE_TRUNC ('day',
downloads.timestamp)::DATE between '2022-07-01' and '2022-09-30' then '2.1.0'
when DATE_TRUNC ('day',
downloads.timestamp)::DATE between '2022-10-01' and '2022-12-31' then '2.2.0'
when DATE_TRUNC ('day',
downloads.timestamp)::DATE between '2023-01-01' and '2023-06-30' then '2.2.0'
when DATE_TRUNC ('day',
downloads.timestamp)::DATE between '2023-07-01' and '2023-12-31' then '2.3.0'
when DATE_TRUNC ('day',
downloads.timestamp)::DATE between '2024-01-01' and '2024-06-30' then '3.0.0'
when DATE_TRUNC ('day',
downloads.timestamp)::DATE between '2024-07-01' and '2024-12-31' then '3.1.0'
when DATE_TRUNC ('day',
downloads.timestamp)::DATE between '2025-01-01' and '2025-06-30' then '4.0.0'
when DATE_TRUNC ('day',
downloads.timestamp)::DATE between '2025-07-01' and '2025-12-31' then '4.1.0'
when DATE_TRUNC ('day',
downloads.timestamp)::DATE between '2026-01-01' and '2025-06-30' then '5.0.0'
when DATE_TRUNC ('day',
downloads.timestamp)::DATE between '2026-07-01' and '2026-12-31' then '5.1.0'
else 'Não Informado (latest)'
end
)
else replace (
SUBSTRING (
context
from
'([0-9]+.[0-9]+.[0-9]+)'
),
'-',
'.'
)
end as versao_pgsys_c,
case
when context like '/pgsys%/pgsmart%pgsmart-agent%' then 'agent'
when context like '/pgsys%/pgsmart%pgsmart-client%' then 'client'
end as arquivo_c,
row_number() over (
partition by (
case
when downloads.email = 'admin'
or downloads.email like 'admin/%' then 'registro@tecnisys.com.br'
when position('/' in downloads.email) > 0 then SUBSTRING(
downloads.email
from
1 for position('/' in downloads.email) - 1
)
else ue.email
end
),
SUBSTRING (
context
from
'([0-9]+.[0-9]+.[0-9]+)-'
),
(
case
when regexp_replace(downloads.context,
'.*/([^/]+)/[^/]+$',
'\1') = 'pgsmart' then regexp_replace(
downloads.context,
'.*/([^/]+)/[^/]+/[^/]+$',
'\1'
)
else regexp_replace(downloads.context,
'.*/([^/]+)/[^/]+$',
'\1')
end
)
order by
timestamp
) as rn_c
from
nexus.downloads
left join (
select
distinct on
(email,
users_id) email,
MIN(users_id) as users_id
from
glpidb.glpi_useremails
group by
email
) ue on
ue.email = (
case
when downloads.email = 'admin'
or downloads.email like 'admin/%' then 'registro@tecnisys.com.br'
when position('/' in downloads.email) > 0 then SUBSTRING(
downloads.email
from
1 for position('/' in downloads.email) - 1
)
else downloads.email
end
)
where
context like '/pgsys%/pgsmart%pgsmart-client%'
order by
timestamp desc
),
pgsmart as (
select
(
case
when downloads.email = 'admin'
or downloads.email like 'admin/%' then 'registro@tecnisys.com.br'
when position('/' in downloads.email) > 0 then SUBSTRING(
downloads.email
from
1 for position('/' in downloads.email) - 1
)
else ue.email
end
) as email_p,
SPLIT_PART(downloads.email,
'/',
2) as ip_p,
case
when downloads.email = 'admin'
and users_id is null
or downloads.email like 'admin/%'
and users_id is null then 1
else ue.users_id
end as users_id_p,
case
when regexp_replace(downloads.context,
'.*/([^/]+)/[^/]+$',
'\1') = 'pgsmart' then regexp_replace(
downloads.context,
'.*/([^/]+)/[^/]+/[^/]+$',
'\1'
)
else regexp_replace(downloads.context,
'.*/([^/]+)/[^/]+$',
'\1')
end as sistema_operacional_p,
context as context_p,
timestamp as data_p,
case
when SUBSTRING (
context
from
'([0-9]+.[0-9]+.[0-9]+)'
) is null
and context like '%/latest%'
or context = '/pgsys' then (
case
when DATE_TRUNC ('day',
downloads.timestamp)::DATE between '2022-01-01' and '2022-03-31' then '1.2.0'
when DATE_TRUNC ('day',
downloads.timestamp)::DATE between '2022-04-01' and '2022-06-30' then '2.0.0'
when DATE_TRUNC ('day',
downloads.timestamp)::DATE between '2022-07-01' and '2022-09-30' then '2.1.0'
when DATE_TRUNC ('day',
downloads.timestamp)::DATE between '2022-10-01' and '2022-12-31' then '2.2.0'
when DATE_TRUNC ('day',
downloads.timestamp)::DATE between '2023-01-01' and '2023-06-30' then '2.2.0'
when DATE_TRUNC ('day',
downloads.timestamp)::DATE between '2023-07-01' and '2023-12-31' then '2.3.0'
when DATE_TRUNC ('day',
downloads.timestamp)::DATE between '2024-01-01' and '2024-06-30' then '3.0.0'
when DATE_TRUNC ('day',
downloads.timestamp)::DATE between '2024-07-01' and '2024-12-31' then '3.1.0'
when DATE_TRUNC ('day',
downloads.timestamp)::DATE between '2025-01-01' and '2025-06-30' then '4.0.0'
when DATE_TRUNC ('day',
downloads.timestamp)::DATE between '2025-07-01' and '2025-12-31' then '4.1.0'
when DATE_TRUNC ('day',
downloads.timestamp)::DATE between '2026-01-01' and '2025-06-30' then '5.0.0'
when DATE_TRUNC ('day',
downloads.timestamp)::DATE between '2026-07-01' and '2026-12-31' then '5.1.0'
else 'Não Informado (latest)'
end
)
else replace (
SUBSTRING (
context
from
'([0-9]+.[0-9]+.[0-9]+)'
),
'-',
'.'
)
end as versao_pgsys_p,
'pgsmart.rpm' as arquivo_p
from
nexus.downloads
left join (
select
distinct on
(email,
users_id) email,
MIN(users_id) as users_id
from
glpidb.glpi_useremails
group by
email
) ue on
ue.email = (
case
when downloads.email = 'admin'
or downloads.email like 'admin/%' then 'registro@tecnisys.com.br'
when position('/' in downloads.email) > 0 then SUBSTRING(
downloads.email
from
1 for position('/' in downloads.email) - 1
)
else downloads.email
end
)
where
context like '/pgsys%/pgsmart%pgsmart-2.%.rpm%'
order by
timestamp desc
),
uniao as (
select
case
when a.arquivo_a is not null
and c.arquivo_c is not null then 'Sim'
when p.arquivo_p is not null then 'Sim'
else 'Não'
end as download_pgsys,
*
from
agent a
full join client c on
a.email_a = c.email_c
and a.versao_pgsys_a = c.versao_pgsys_c
and a.rn_a = c.rn_c
and a.sistema_operacional_a = c.sistema_operacional_c
full join pgsmart p on
c.email_c = p.email_p
and c.versao_pgsys_c = p.versao_pgsys_p
order by
data_a desc,
download_pgsys desc
)
select
download_pgsys,
coalesce (email_a,
email_c,
email_p) as email,
coalesce (ip_p,
ip_a,
ip_c) as ip,
coalesce (users_id_a,
users_id_c,
users_id_p) as users_id,
case
when context_p is not null then REGEXP_SUBSTR(context_p,
'pgsmart-.*$',
1)
when context_a is not null
and context_c is not null then REGEXP_SUBSTR(context_a,
'pgsmart-.*$',
1) || ' --- ' || REGEXP_SUBSTR(context_c,
'pgsmart-.*$',
1)
else REGEXP_SUBSTR(
coalesce (context_a,
context_c),
'pgsmart-.*$',
1
)
end as arquivos_baixados,
data_a,
data_c,
data_p,
greatest (data_p,
data_a,
data_c) as data,
coalesce (versao_pgsys_p,
versao_pgsys_a,
versao_pgsys_c) as versao_pgsys,
coalesce (
sistema_operacional_p,
sistema_operacional_a,
sistema_operacional_c
) as sistema_operacional,
case
when arquivo_p is not null then arquivo_p
when arquivo_a is not null
and arquivo_c is not null then arquivo_a || '(' || rn_a || '°)' || ' + ' || arquivo_c || '(' || rn_c || '°)'
else coalesce (arquivo_a,
arquivo_c) || '(' || coalesce (rn_a,
rn_c) || '°)'
end as arquivos
from
uniao
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