-
Notifications
You must be signed in to change notification settings - Fork 1
Commit
This commit does not belong to any branch on this repository, and may belong to a fork outside of the repository.
Bilhetagem Jaé - Adiciona tipo da gratuidade e materializa passageiro…
…s_hora (#206) * adiciona gratuidade na tabela transacao * adiciona gratuidade * cria tabela staging gratuidade * rho corrige logica particao * ajustes gratuidade * ajusta logica partição rho sppo * materializar passageiros_hora * corte integracao * altera source para prod
- Loading branch information
Showing
9 changed files
with
369 additions
and
59 deletions.
There are no files selected for viewing
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
92 changes: 92 additions & 0 deletions
92
models/br_rj_riodejaneiro_bilhetagem_staging/gratuidade_aux.sql
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -0,0 +1,92 @@ | ||
{{ | ||
config( | ||
materialized="incremental", | ||
incremental_strategy="insert_overwrite", | ||
partition_by={ | ||
"field": "id_cliente", | ||
"data_type": "int64", | ||
"range": { | ||
"start": 0, | ||
"end": 100000000, | ||
"interval": 10000 | ||
} | ||
}, | ||
) | ||
}} | ||
|
||
|
||
{% set staging_gratuidade = ref('staging_gratuidade') %} | ||
|
||
{% set incremental_filter %} | ||
DATE(data) BETWEEN DATE("{{var('date_range_start')}}") AND DATE("{{var('date_range_end')}}") | ||
AND timestamp_captura BETWEEN DATETIME("{{var('date_range_start')}}") AND DATETIME("{{var('date_range_end')}}") | ||
{% endset %} | ||
|
||
{% if execute %} | ||
{% if is_incremental() %} | ||
{% set partitions_query %} | ||
SELECT DISTINCT | ||
CAST(CAST(cd_cliente AS FLOAT64) AS INT64) AS cd_cliente | ||
FROM | ||
{{ staging_gratuidade }} | ||
WHERE | ||
{{ incremental_filter }} | ||
{% endset %} | ||
|
||
{% set partitions = run_query(partitions_query) %} | ||
|
||
{% set partition_list = partitions.columns[0].values() %} | ||
{% endif %} | ||
{% endif %} | ||
|
||
WITH gratuidade_complete_partitions AS ( | ||
SELECT | ||
CAST(CAST(cd_cliente AS FLOAT64) AS INT64) AS id_cliente, | ||
id AS id_gratuidade, | ||
tipo_gratuidade, | ||
data_inclusao AS data_inicio_validade, | ||
timestamp_captura | ||
FROM | ||
{{ staging_gratuidade }} | ||
{% if is_incremental() -%} | ||
WHERE | ||
{{ incremental_filter }} | ||
|
||
{% if partition_list|length > 0 -%} | ||
UNION ALL | ||
|
||
SELECT | ||
id_cliente, | ||
id_gratuidade, | ||
tipo_gratuidade, | ||
data_inicio_validade, | ||
timestamp_captura | ||
FROM | ||
{{ this }} | ||
WHERE | ||
id_cliente IN ({{ partition_list|join(', ') }}) | ||
{%- endif %} | ||
{%- endif %} | ||
), | ||
gratuidade_deduplicada AS ( | ||
SELECT | ||
* EXCEPT(rn) | ||
FROM | ||
( | ||
SELECT | ||
*, | ||
ROW_NUMBER() OVER (PARTITION BY id_gratuidade ORDER BY timestamp_captura DESC) AS rn | ||
FROM | ||
gratuidade_complete_partitions | ||
) | ||
WHERE | ||
rn = 1 | ||
) | ||
SELECT | ||
id_cliente, | ||
tipo_gratuidade, | ||
data_inicio_validade, | ||
LEAD(data_inicio_validade) OVER (PARTITION BY id_cliente ORDER BY data_inicio_validade) AS data_fim_validade, | ||
timestamp_captura | ||
FROM | ||
gratuidade_complete_partitions |
18 changes: 18 additions & 0 deletions
18
models/br_rj_riodejaneiro_bilhetagem_staging/staging_gratuidade.sql
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -0,0 +1,18 @@ | ||
{{ | ||
config( | ||
alias='gratuidade', | ||
) | ||
}} | ||
|
||
SELECT | ||
data, | ||
SAFE_CAST(id AS STRING) AS id, | ||
DATETIME(PARSE_TIMESTAMP('%Y-%m-%d %H:%M:%S%Ez', timestamp_captura), "America/Sao_Paulo") AS timestamp_captura, | ||
SAFE_CAST(JSON_VALUE(content, '$.cd_cliente') AS STRING) AS cd_cliente, | ||
DATETIME(PARSE_TIMESTAMP('%Y-%m-%dT%H:%M:%E*S%Ez', SAFE_CAST(JSON_VALUE(content, '$.data_inclusao') AS STRING)), 'America/Sao_Paulo') AS data_inclusao, | ||
SAFE_CAST(JSON_VALUE(content, '$.id_status_gratuidade') AS STRING) AS id_status_gratuidade, | ||
SAFE_CAST(JSON_VALUE(content, '$.id_tipo_gratuidade') AS STRING) AS id_tipo_gratuidade, | ||
SAFE_CAST(JSON_VALUE(content, '$.tipo_gratuidade') AS STRING) AS tipo_gratuidade | ||
FROM | ||
{{ source('br_rj_riodejaneiro_bilhetagem_staging', 'gratuidade') }} | ||
|
Oops, something went wrong.