diff --git a/models/core/core__fact_dex_swaps.sql b/models/core/core__fact_dex_swaps.sql new file mode 100644 index 0000000..4637b2d --- /dev/null +++ b/models/core/core__fact_dex_swaps.sql @@ -0,0 +1,27 @@ +{{ config( + materialized = 'view', + secure = true +) }} + +WITH dex_swaps AS ( + + SELECT + * + FROM + {{ ref('silver__dex_swaps') }} +) +SELECT + block_id, + block_timestamp, + tx_hash, + action_id, + tx_signer, + tx_receiver, + pool_id, + token_in, + amount_in, + token_out, + amount_out, + swap_index +FROM + dex_swaps diff --git a/models/core/core__fact_dex_swaps.yml b/models/core/core__fact_dex_swaps.yml new file mode 100644 index 0000000..26bf5d8 --- /dev/null +++ b/models/core/core__fact_dex_swaps.yml @@ -0,0 +1,114 @@ +version: 2 + +models: + - name: core__fact_dex_swaps + description: |- + This table records all the swap transactions occurring in NEAR. + tests: + - dbt_utils.unique_combination_of_columns: + combination_of_columns: + - action_id + + columns: + - name: BLOCK_ID + description: "{{ doc('block_id')}}" + tests: + - not_null + - dbt_expectations.expect_column_values_to_be_in_type_list: + column_type_list: + - NUMBER + - FLOAT + + - name: BLOCK_TIMESTAMP + description: "{{ doc('block_timestamp')}}" + tests: + - not_null + - dbt_expectations.expect_column_values_to_be_in_type_list: + column_type_list: + - TIMESTAMP_NTZ + + - name: TX_HASH + description: "{{ doc('tx_hash')}}" + tests: + - not_null + - dbt_expectations.expect_column_values_to_be_in_type_list: + column_type_list: + - STRING + - VARCHAR + + - name: ACTION_ID + description: "{{ doc('action_id')}}" + tests: + - not_null + - unique + - dbt_expectations.expect_column_values_to_be_in_type_list: + column_type_list: + - STRING + - VARCHAR + + - name: TX_SIGNER + description: "{{ doc('tx_signer')}}" + tests: + - not_null + - dbt_expectations.expect_column_values_to_be_in_type_list: + column_type_list: + - STRING + - VARCHAR + + - name: TX_RECEIVER + description: "{{ doc('tx_receiver')}}" + tests: + - not_null + - dbt_expectations.expect_column_values_to_be_in_type_list: + column_type_list: + - STRING + - VARCHAR + + - name: POOL_ID + description: "{{ doc('pool_id')}}" + tests: + - not_null + - dbt_expectations.expect_column_values_to_be_in_type_list: + column_type_list: + - NUMBER + + - name: TOKEN_IN + description: "{{ doc('token_in')}}" + tests: + - dbt_expectations.expect_column_values_to_be_in_type_list: + column_type_list: + - STRING + - VARCHAR + + - name: AMOUNT_IN + description: "{{ doc('amount_in')}}" + tests: + - dbt_expectations.expect_column_values_to_be_in_type_list: + column_type_list: + - NUMBER + - FLOAT + + - name: TOKEN_OUT + description: "{{ doc('token_out')}}" + tests: + - dbt_expectations.expect_column_values_to_be_in_type_list: + column_type_list: + - STRING + - VARCHAR + + - name: AMOUNT_OUT + description: "{{ doc('amount_out')}}" + tests: + - not_null + - dbt_expectations.expect_column_values_to_be_in_type_list: + column_type_list: + - NUMBER + - FLOAT + + - name: SWAP_INDEX + description: "{{ doc('swap_index')}}" + tests: + - not_null + - dbt_expectations.expect_column_values_to_be_in_type_list: + column_type_list: + - NUMBER diff --git a/models/descriptions/_insterted_timestamp.md b/models/descriptions/_inserted_timestamp.md similarity index 100% rename from models/descriptions/_insterted_timestamp.md rename to models/descriptions/_inserted_timestamp.md diff --git a/models/descriptions/amount_in.md b/models/descriptions/amount_in.md new file mode 100644 index 0000000..c548274 --- /dev/null +++ b/models/descriptions/amount_in.md @@ -0,0 +1,5 @@ +{% docs amount_in %} + +The amount of tokens put into the swap. + +{% enddocs %} diff --git a/models/descriptions/amount_out.md b/models/descriptions/amount_out.md new file mode 100644 index 0000000..2f8bc30 --- /dev/null +++ b/models/descriptions/amount_out.md @@ -0,0 +1,5 @@ +{% docs amount_out %} + +The amount of tokens taken out of or received from the swap. + +{% enddocs %} diff --git a/models/descriptions/pool_id.md b/models/descriptions/pool_id.md new file mode 100644 index 0000000..eca08fd --- /dev/null +++ b/models/descriptions/pool_id.md @@ -0,0 +1,5 @@ +{% docs pool_id %} + +The unique id for the pool involved in the swap. + +{% enddocs %} diff --git a/models/descriptions/swap_index.md b/models/descriptions/swap_index.md new file mode 100644 index 0000000..6c689c8 --- /dev/null +++ b/models/descriptions/swap_index.md @@ -0,0 +1,5 @@ +{% docs swap_index %} + +The index number of the swap indicating its order of execution in the transaction. + +{% enddocs %} diff --git a/models/descriptions/token_in.md b/models/descriptions/token_in.md new file mode 100644 index 0000000..f778dc0 --- /dev/null +++ b/models/descriptions/token_in.md @@ -0,0 +1,5 @@ +{% docs token_in %} + +The address of the token sent for swap. + +{% enddocs %} diff --git a/models/descriptions/token_out.md b/models/descriptions/token_out.md new file mode 100644 index 0000000..595b2be --- /dev/null +++ b/models/descriptions/token_out.md @@ -0,0 +1,5 @@ +{% docs token_out %} + +The address of the token being swapped to. + +{% enddocs %} diff --git a/models/silver/silver__dex_swaps.sql b/models/silver/silver__dex_swaps.sql new file mode 100644 index 0000000..be757f4 --- /dev/null +++ b/models/silver/silver__dex_swaps.sql @@ -0,0 +1,127 @@ +{{ config( + materialized = "incremental", + unique_key = "action_id", + incremental_strategy = "delete+insert", + cluster_by = ["block_timestamp::DATE", "_inserted_timestamp::DATE"], +) }} + +WITH actions AS ( + + SELECT + block_id, + block_timestamp, + tx_hash, + action_id, + args, + NULLIF( + j.value :amount_in, + NULL + ) :: bigint AS amount_in, + NULLIF( + j.value :min_amount_out, + NULL + ) :: bigint AS amount_out, + NULLIF( + j.value :pool_id, + NULL + ) :: text AS pool_id, + NULLIF( + j.value :token_in, + NULL + ) :: text AS token_in, + NULLIF( + j.value :token_out, + NULL + ) :: text AS token_out, + j.index AS swap_index, + _inserted_timestamp + FROM + {{ ref("silver__actions_events_function_call") }}, + LATERAL FLATTEN(input => PARSE_JSON(args) :actions) j + WHERE + method_name = 'swap' + AND args LIKE '%actions%' + AND {{ incremental_load_filter("_inserted_timestamp") }} +), +receipts AS ( + SELECT + block_id, + block_timestamp, + tx_hash, + CASE + WHEN PARSE_JSON( + receipts.status_value + ) :Failure IS NOT NULL THEN 'Fail' + ELSE 'Success' + END AS success_or_fail, + logs + FROM + {{ ref("silver__receipts") }} + WHERE + {{ incremental_load_filter("_inserted_timestamp") }} +), +transactions AS ( + SELECT + block_id, + block_timestamp, + tx_hash, + tx_signer, + tx_receiver + FROM + {{ ref("silver__transactions") }} + WHERE + {{ incremental_load_filter("_inserted_timestamp") }} +), +final_table AS ( + SELECT + DISTINCT actions.swap_index, + actions.block_id, + actions.block_timestamp, + actions.tx_hash, + actions.action_id, + transactions.tx_signer, + transactions.tx_receiver, + LAST_VALUE( + receipts.success_or_fail + ) over ( + PARTITION BY receipts.tx_hash + ORDER BY + receipts.success_or_fail DESC + ) AS txn_status, + actions.pool_id, + actions.amount_in, + actions.amount_out, + actions.token_in, + actions.token_out, + actions._inserted_timestamp + FROM + actions + JOIN receipts + ON actions.tx_hash = receipts.tx_hash + JOIN transactions + ON actions.tx_hash = transactions.tx_hash + ORDER BY + tx_hash, + swap_index +) +SELECT + block_id, + block_timestamp, + tx_hash, + action_id, + tx_signer, + tx_receiver, + pool_id, + token_in, + amount_in, + token_out, + amount_out, + swap_index, + _inserted_timestamp +FROM + final_table +WHERE + txn_status = 'Success' +ORDER BY + tx_hash, + swap_index diff --git a/models/silver/silver__dex_swaps.yml b/models/silver/silver__dex_swaps.yml new file mode 100644 index 0000000..c51cbe1 --- /dev/null +++ b/models/silver/silver__dex_swaps.yml @@ -0,0 +1,122 @@ +version: 2 + +models: + - name: silver__dex_swaps + description: |- + This table records all the swap transactions occurring in NEAR. + tests: + - dbt_utils.unique_combination_of_columns: + combination_of_columns: + - action_id + + columns: + - name: BLOCK_ID + description: "{{ doc('block_id')}}" + tests: + - not_null + - dbt_expectations.expect_column_values_to_be_in_type_list: + column_type_list: + - NUMBER + - FLOAT + + - name: BLOCK_TIMESTAMP + description: "{{ doc('block_timestamp')}}" + tests: + - not_null + - dbt_expectations.expect_column_values_to_be_in_type_list: + column_type_list: + - TIMESTAMP_NTZ + + - name: TX_HASH + description: "{{ doc('tx_hash')}}" + tests: + - not_null + - dbt_expectations.expect_column_values_to_be_in_type_list: + column_type_list: + - STRING + - VARCHAR + + - name: ACTION_ID + description: "{{ doc('action_id')}}" + tests: + - not_null + - unique + - dbt_expectations.expect_column_values_to_be_in_type_list: + column_type_list: + - STRING + - VARCHAR + + - name: TX_SIGNER + description: "{{ doc('tx_signer')}}" + tests: + - not_null + - dbt_expectations.expect_column_values_to_be_in_type_list: + column_type_list: + - STRING + - VARCHAR + + - name: TX_RECEIVER + description: "{{ doc('tx_receiver')}}" + tests: + - not_null + - dbt_expectations.expect_column_values_to_be_in_type_list: + column_type_list: + - STRING + - VARCHAR + + - name: POOL_ID + description: "{{ doc('pool_id')}}" + tests: + - dbt_expectations.expect_column_values_to_be_in_type_list: + column_type_list: + - NUMBER + + - name: TOKEN_IN + description: "{{ doc('token_in')}}" + tests: + - dbt_expectations.expect_column_values_to_be_in_type_list: + column_type_list: + - STRING + - VARCHAR + + - name: AMOUNT_IN + description: "{{ doc('amount_in')}}" + tests: + - not_null + - dbt_expectations.expect_column_values_to_be_in_type_list: + column_type_list: + - NUMBER + - FLOAT + + - name: TOKEN_OUT + description: "{{ doc('token_out')}}" + tests: + - dbt_expectations.expect_column_values_to_be_in_type_list: + column_type_list: + - STRING + - VARCHAR + + - name: AMOUNT_OUT + description: "{{ doc('amount_out')}}" + tests: + - not_null + - dbt_expectations.expect_column_values_to_be_in_type_list: + column_type_list: + - NUMBER + - FLOAT + + - name: SWAP_INDEX + description: "{{ doc('swap_index')}}" + tests: + - not_null + - dbt_expectations.expect_column_values_to_be_in_type_list: + column_type_list: + - NUMBER + + - name: _INSERTED_TIMESTAMP + description: "{{ doc('_inserted_timestamp')}}" + tests: + - not_null + - dbt_expectations.expect_column_values_to_be_in_type_list: + column_type_list: + - TIMESTAMP_NTZ