mirror of
https://github.com/FlipsideCrypto/flow-models.git
synced 2026-02-06 11:06:45 +00:00
* add: model to backfill * fix: node's string format * add tags * upd collection model * mainnet21 hardcoded collections history model * del tag * mainnet 21 getblock * tag for 21 * realtime models * alias num as height * realtime tags * add missing tag and newlines * backfiller * backfiller * move script to folder (renamed) python, upd test accordingly w dir name ch * upd script to accept model input, update jobs per method call * error w use_dev arg * add: silver mdoels * limit backfill job in python script * rename silver dbt models to streamline_ and move into silver/core * explicit casting to silver streamline models * add documentation to silver streamline models * run only current mainnet and history mainnet 22 first * activate schedule for gha * del hardcoded mainnet models * move history modes out of subdirs into history dir * fix GHA vars * del upstream 1+ from history step * del tag --------- Co-authored-by: Jack Forgash <jmfxyz@pm.me>
124 lines
2.2 KiB
SQL
124 lines
2.2 KiB
SQL
{{ config(
|
|
materialized = 'incremental',
|
|
cluster_by = ['_inserted_timestamp::DATE'],
|
|
unique_key = 'tx_id',
|
|
incremental_strategy = 'delete+insert',
|
|
tags = ['scheduled']
|
|
) }}
|
|
|
|
WITH bronze_txs AS (
|
|
|
|
SELECT
|
|
*
|
|
FROM
|
|
{{ ref('bronze__transactions') }}
|
|
|
|
{% if is_incremental() %}
|
|
WHERE
|
|
_inserted_timestamp >= (
|
|
SELECT
|
|
MAX(_inserted_timestamp)
|
|
FROM
|
|
{{ this }}
|
|
)
|
|
{% endif %}
|
|
|
|
qualify ROW_NUMBER() over (
|
|
PARTITION BY tx_id
|
|
ORDER BY
|
|
_ingested_at DESC
|
|
) = 1
|
|
),
|
|
silver_txs AS (
|
|
SELECT
|
|
tx_id,
|
|
block_timestamp,
|
|
block_id AS block_height,
|
|
chain_id,
|
|
tx_block_index AS tx_index,
|
|
COALESCE(
|
|
tx :proposal_key :Address,
|
|
tx :proposalKeyAddress
|
|
) :: STRING AS proposer,
|
|
tx :payer :: STRING AS payer,
|
|
tx :authorizers :: ARRAY AS authorizers,
|
|
ARRAY_SIZE(authorizers) AS count_authorizers,
|
|
COALESCE(
|
|
tx :gas_limit,
|
|
tx :gasLimit
|
|
) :: NUMBER AS gas_limit,
|
|
COALESCE(
|
|
tx :transaction_result,
|
|
tx :result
|
|
) :: variant AS transaction_result,
|
|
CASE
|
|
WHEN transaction_result :error = '' THEN TRUE
|
|
WHEN transaction_result :error :: STRING IS NULL THEN TRUE
|
|
ELSE FALSE
|
|
END AS tx_succeeded,
|
|
COALESCE(
|
|
transaction_result :error,
|
|
''
|
|
) :: STRING AS error_msg,
|
|
_ingested_at,
|
|
_inserted_timestamp
|
|
FROM
|
|
bronze_txs
|
|
),
|
|
concat_authorizers AS (
|
|
SELECT
|
|
tx_id,
|
|
CONCAT(
|
|
'0x',
|
|
VALUE
|
|
) AS x_auth
|
|
FROM
|
|
silver_txs,
|
|
LATERAL FLATTEN (
|
|
input => authorizers
|
|
)
|
|
),
|
|
authorizers_array AS (
|
|
SELECT
|
|
tx_id,
|
|
ARRAY_AGG(x_auth) AS authorizers
|
|
FROM
|
|
concat_authorizers
|
|
GROUP BY
|
|
1
|
|
),
|
|
FINAL AS (
|
|
SELECT
|
|
t.tx_id,
|
|
block_timestamp,
|
|
block_height,
|
|
chain_id,
|
|
tx_index,
|
|
CONCAT(
|
|
'0x',
|
|
proposer
|
|
) AS proposer,
|
|
CONCAT(
|
|
'0x',
|
|
payer
|
|
) AS payer,
|
|
COALESCE(
|
|
aa.authorizers,
|
|
t.authorizers
|
|
) AS authorizers,
|
|
count_authorizers,
|
|
gas_limit,
|
|
transaction_result,
|
|
tx_succeeded,
|
|
error_msg,
|
|
_ingested_at,
|
|
_inserted_timestamp
|
|
FROM
|
|
silver_txs t
|
|
LEFT JOIN authorizers_array aa USING (tx_id)
|
|
)
|
|
SELECT
|
|
*
|
|
FROM
|
|
FINAL
|