near-models/models/silver/core/silver__transactions_final.sql

147 lines
3.7 KiB
MySQL
Raw Normal View History

{{ config(
materialized = 'incremental',
2025-02-19 23:29:23 +00:00
incremental_predicates = ["dynamic_range_predicate","block_timestamp::date"],
incremental_strategy = 'merge',
merge_exclude_columns = ['inserted_timestamp'],
unique_key = 'tx_hash',
2025-02-19 23:29:23 +00:00
cluster_by = ['block_timestamp::DATE','modified_timestamp::DATE'],
2025-03-03 18:41:11 +00:00
post_hook = "ALTER TABLE {{ this }} ADD SEARCH OPTIMIZATION ON EQUALITY(tx_hash,tx_signer,tx_receiver);",
2025-03-10 03:07:50 +00:00
tags = ['scheduled_core', 'core_v2'],
2025-03-03 20:45:25 +00:00
full_refresh = false
) }}
2025-02-19 22:43:11 +00:00
{% if var('NEAR_MIGRATE_ARCHIVE', False) %}
2025-03-03 19:28:41 +00:00
{% if execute %}
{% do log('Migrating transactions ' ~ var('RANGE_START') ~ ' to ' ~ var('RANGE_END'), info=True) %}
{% do log('Invocation ID: ' ~ invocation_id, info=True) %}
{% endif %}
2025-02-19 22:43:11 +00:00
SELECT
2025-02-19 22:43:11 +00:00
chunk_hash,
block_id,
block_timestamp,
tx_hash,
2025-03-03 18:41:11 +00:00
tx_receiver,
tx_signer,
transaction_json,
2025-02-19 22:43:11 +00:00
outcome_json,
OBJECT_CONSTRUCT() AS status_json,
tx_succeeded,
gas_used,
transaction_fee,
attached_gas,
_partition_by_block_number,
2025-03-03 18:41:11 +00:00
transactions_final_id,
inserted_timestamp,
2025-03-03 17:13:44 +00:00
modified_timestamp,
2025-02-19 22:43:11 +00:00
'{{ invocation_id }}' AS _invocation_id
FROM
2025-02-19 22:43:11 +00:00
{{ ref('_migrate_txs') }}
{% else %}
WITH txs_with_receipts AS (
SELECT
2025-02-19 22:43:11 +00:00
chunk_hash,
origin_block_id AS block_id,
origin_block_timestamp AS block_timestamp,
tx_hash,
2025-02-19 22:43:11 +00:00
response_json :transaction :: variant AS transaction_json,
response_json :transaction_outcome :outcome :: variant AS outcome_json,
response_json :status :: variant AS status_json,
response_json :receipts_outcome :: ARRAY AS receipts_outcome_json,
response_json :status :Failure IS NULL AS tx_succeeded,
partition_key AS _partition_by_block_number
FROM
2025-02-19 22:43:11 +00:00
{{ ref('silver__transactions_v2') }}
2025-02-19 23:10:42 +00:00
{% if is_incremental() %}
2025-02-19 22:43:11 +00:00
WHERE
modified_timestamp >= (
SELECT
2025-03-04 17:18:51 +00:00
COALESCE(MAX(modified_timestamp), '1970-01-01')
2025-02-19 22:43:11 +00:00
FROM
{{ this }}
)
{% endif %}
2025-02-19 23:10:42 +00:00
),
2025-02-19 22:43:11 +00:00
determine_receipt_gas_burnt AS (
SELECT
tx_hash,
2025-02-19 22:43:11 +00:00
SUM(
2025-03-03 19:03:36 +00:00
ZEROIFNULL(VALUE :outcome :gas_burnt :: INT)
2025-02-19 22:43:11 +00:00
) AS total_gas_burnt_receipts,
SUM(
2025-03-03 19:03:36 +00:00
ZEROIFNULL(VALUE :outcome :tokens_burnt :: INT)
2025-02-19 22:43:11 +00:00
) AS total_tokens_burnt_receipts
FROM
2025-02-19 22:43:11 +00:00
txs_with_receipts,
LATERAL FLATTEN (
input => receipts_outcome_json
)
GROUP BY
1
),
2025-02-19 22:43:11 +00:00
determine_attached_gas AS (
SELECT
2025-02-19 22:43:11 +00:00
tx_hash,
SUM(
VALUE :FunctionCall :gas :: INT
) AS total_attached_gas
FROM
2025-02-19 22:43:11 +00:00
txs_with_receipts,
LATERAL FLATTEN (
input => transaction_json :actions :: ARRAY
)
GROUP BY
1
),
2025-02-19 22:43:11 +00:00
transactions_final AS (
SELECT
2025-02-19 22:43:11 +00:00
chunk_hash,
block_id,
block_timestamp,
t.tx_hash,
2025-02-19 22:43:11 +00:00
transaction_json,
outcome_json,
status_json,
total_gas_burnt_receipts,
total_tokens_burnt_receipts,
total_attached_gas,
tx_succeeded,
_partition_by_block_number
FROM
2025-02-19 22:43:11 +00:00
txs_with_receipts t
LEFT JOIN determine_receipt_gas_burnt d USING (tx_hash)
LEFT JOIN determine_attached_gas A USING (tx_hash)
)
SELECT
2025-02-19 22:43:11 +00:00
chunk_hash,
block_id,
block_timestamp,
2025-02-19 22:43:11 +00:00
tx_hash,
2025-03-03 18:41:11 +00:00
transaction_json :receiver_id :: STRING AS tx_receiver,
transaction_json :signer_id :: STRING AS tx_signer,
transaction_json,
2025-02-19 22:43:11 +00:00
outcome_json,
status_json,
tx_succeeded,
2025-03-03 19:03:36 +00:00
ZEROIFNULL(outcome_json :gas_burnt :: INT) + total_gas_burnt_receipts AS gas_used,
ZEROIFNULL(outcome_json :tokens_burnt :: INT) + total_tokens_burnt_receipts AS transaction_fee,
2025-02-19 22:43:11 +00:00
COALESCE(
total_attached_gas,
gas_used
) AS attached_gas,
_partition_by_block_number,
{{ dbt_utils.generate_surrogate_key(
['tx_hash']
2025-02-19 22:43:11 +00:00
) }} AS transactions_final_id,
SYSDATE() AS inserted_timestamp,
SYSDATE() AS modified_timestamp,
'{{ invocation_id }}' AS _invocation_id
FROM
2025-02-19 22:43:11 +00:00
transactions_final
2025-02-19 23:51:46 +00:00
2025-02-19 22:43:11 +00:00
{% endif %}