diff --git a/models/descriptions/__overview__.md b/models/descriptions/__overview__.md index 910ab5f..2d01b1d 100644 --- a/models/descriptions/__overview__.md +++ b/models/descriptions/__overview__.md @@ -35,6 +35,7 @@ There is more information on how to use dbt docs in the last section of this doc **Fact Tables:** - [defi.fact_swaps](https://flipsidecrypto.github.io/aleo-models/#!/model/model.aleo_models.defi__fact_swaps) +- [defi.fact_liquidity_actions](https://flipsidecrypto.github.io/aleo-models/#!/model/model.aleo_models.defi__fact_liquidity_actions) ### Price Tables (`aleo`.`PRICE`.``) diff --git a/models/gold/core/core__dim_token_registrations.sql b/models/gold/core/core__dim_token_registrations.sql index 6389337..1259715 100644 --- a/models/gold/core/core__dim_token_registrations.sql +++ b/models/gold/core/core__dim_token_registrations.sql @@ -3,36 +3,41 @@ unique_key = ['dim_token_registrations_id'], incremental_strategy = 'merge', merge_exclude_columns = ['inserted_timestamp'], + cluster_by = ['token_name'], tags = ['core','full_test'] ) }} -SELECT - tx_id, - block_id, - block_timestamp, - token_id, - decode_u128_to_ascii(name_encoded) as token_name, - decode_u128_to_ascii(symbol_encoded) as symbol, - decimals, - max_supply, - external_auth_required, - external_auth_party, - name_encoded, - symbol_encoded, - {{ dbt_utils.generate_surrogate_key( - ['token_id'] - ) }} AS dim_token_registrations_id, - SYSDATE() AS inserted_timestamp, - SYSDATE() AS modified_timestamp, - '{{ invocation_id }}' AS invocation_id -FROM - {{ ref('silver__token_registrations') }} +WITH token_registrations AS ( + SELECT + tx_id_created, + block_id_created, + block_timestamp_created, + token_id, + token_name, + symbol, + decimals, + max_supply, + external_auth_required, + external_auth_party, + name_encoded, + symbol_encoded, + {{ dbt_utils.generate_surrogate_key( + ['token_id'] + ) }} AS dim_token_registrations_id, + SYSDATE() AS inserted_timestamp, + SYSDATE() AS modified_timestamp, + '{{ invocation_id }}' AS invocation_id + FROM + {{ ref('silver__token_registrations') }} -{% if is_incremental() %} -WHERE - modified_timestamp >= ( - SELECT - MAX(modified_timestamp) - FROM {{ this }} - ) -{% endif %} \ No newline at end of file + {% if is_incremental() %} + WHERE + modified_timestamp >= ( + SELECT + MAX(modified_timestamp) + FROM {{ this }} + ) + {% endif %} +) + +SELECT * FROM token_registrations diff --git a/models/gold/core/core__dim_token_registrations.yml b/models/gold/core/core__dim_token_registrations.yml index f48fcea..3e283ed 100644 --- a/models/gold/core/core__dim_token_registrations.yml +++ b/models/gold/core/core__dim_token_registrations.yml @@ -4,18 +4,18 @@ models: - name: core__dim_token_registrations description: Dimension table containing information about token registrations on the network. columns: - - name: TX_ID - description: "{{ doc('tx_id') }}" + - name: TX_ID_CREATED + description: "Transaction ID when the token was created" tests: - dbt_expectations.expect_column_to_exist - - name: BLOCK_ID - description: "{{ doc('block_id') }}" + - name: BLOCK_ID_CREATED + description: "Block ID when the token was created" tests: - dbt_expectations.expect_column_to_exist - - name: BLOCK_TIMESTAMP - description: "{{ doc('block_timestamp') }}" + - name: BLOCK_TIMESTAMP_CREATED + description: "Block timestamp when the token was created" tests: - dbt_expectations.expect_column_to_exist @@ -23,6 +23,8 @@ models: description: "The ID of the token" tests: - dbt_expectations.expect_column_to_exist + - not_null + - unique - name: TOKEN_NAME description: "The decoded name of the token" diff --git a/models/gold/defi/defi__fact_liquidity_pool_actions.sql b/models/gold/defi/defi__fact_liquidity_pool_actions.sql index d91eb54..dd00e38 100644 --- a/models/gold/defi/defi__fact_liquidity_pool_actions.sql +++ b/models/gold/defi/defi__fact_liquidity_pool_actions.sql @@ -10,7 +10,7 @@ ) }} WITH arcane AS ( - SELECT + SELECT block_timestamp, block_id, tx_id, @@ -24,7 +24,7 @@ WITH arcane AS ( token2_name, token1_amount, token2_amount, - 'Arcane Finance' as liquidity_pool_protocol + 'Arcane Finance' AS liquidity_pool_protocol FROM {{ ref('silver__liquidity_pool_actions_arcane') }} diff --git a/models/gold/tests/defi/test_defi__liquidity_actions_recent.yml b/models/gold/tests/defi/test_defi__liquidity_actions_recent.yml index 2636374..6bd6a9d 100644 --- a/models/gold/tests/defi/test_defi__liquidity_actions_recent.yml +++ b/models/gold/tests/defi/test_defi__liquidity_actions_recent.yml @@ -17,4 +17,60 @@ models: - not_null - dbt_expectations.expect_row_values_to_have_recent_data: datepart: hour - interval: 3 \ No newline at end of file + interval: 3 + + - name: block_id + tests: + - not_null + + - name: tx_id + tests: + - not_null + + - name: succeeded + tests: + - not_null + + - name: root_action + tests: + - not_null + + - name: liquidity_action + tests: + - not_null + + - name: liquidity_provider + tests: + - not_null + + - name: token1_amount + tests: + - not_null + + - name: token1_name + tests: + - not_null + + - name: token1_id + tests: + - not_null + + - name: token2_amount + tests: + - not_null + + - name: token2_name + tests: + - not_null + + - name: token2_id + tests: + - not_null + + - name: inserted_timestamp + tests: + - not_null + + - name: modified_timestamp + tests: + - not_null \ No newline at end of file diff --git a/models/gold/tests/tokens/test_core__token_registrations_recent.sql b/models/gold/tests/tokens/test_core__token_registrations_recent.sql new file mode 100644 index 0000000..34ffe11 --- /dev/null +++ b/models/gold/tests/tokens/test_core__token_registrations_recent.sql @@ -0,0 +1,27 @@ +{{ config ( + materialized = 'view', + tags = ['recent_test'] +) }} + +WITH last_3_days AS ( + + SELECT + block_date + FROM + {{ ref("_max_block_by_date") }} + qualify ROW_NUMBER() over ( + ORDER BY + block_date DESC + ) = 3 +) +SELECT + * +FROM + {{ ref('core__dim_token_registrations') }} +WHERE + block_timestamp_created :: DATE >= ( + SELECT + block_date + FROM + last_3_days + ) diff --git a/models/gold/tests/tokens/test_core__token_registrations_recent.yml b/models/gold/tests/tokens/test_core__token_registrations_recent.yml new file mode 100644 index 0000000..dee1fa7 --- /dev/null +++ b/models/gold/tests/tokens/test_core__token_registrations_recent.yml @@ -0,0 +1,75 @@ +version: 2 + +models: + - name: test_core__token_registrations_recent + description: Tests for the recent view of the token registrations model. + tests: + - dbt_utils.unique_combination_of_columns: + combination_of_columns: + - TX_ID_CREATED + - TOKEN_ID + columns: + - name: BLOCK_ID_CREATED + tests: + - not_null + + - name: BLOCK_TIMESTAMP_CREATED + tests: + - not_null + - dbt_expectations.expect_row_values_to_have_recent_data: + datepart: hour + interval: 3 + + - name: TX_ID_CREATED + tests: + - not_null + - unique + + - name: TOKEN_ID + tests: + - dbt_expectations.expect_column_to_exist + + - name: TOKEN_NAME + tests: + - dbt_expectations.expect_column_to_exist + + - name: SYMBOL + tests: + - dbt_expectations.expect_column_to_exist + + - name: DECIMALS + tests: + - dbt_expectations.expect_column_to_exist + + - name: MAX_SUPPLY + tests: + - dbt_expectations.expect_column_to_exist + + - name: EXTERNAL_AUTH_REQUIRED + tests: + - dbt_expectations.expect_column_to_exist + + - name: EXTERNAL_AUTH_PARTY + tests: + - dbt_expectations.expect_column_to_exist + + - name: NAME_ENCODED + tests: + - dbt_expectations.expect_column_to_exist + + - name: SYMBOL_ENCODED + tests: + - dbt_expectations.expect_column_to_exist + + - name: DIM_TOKEN_REGISTRATIONS_ID + tests: + - unique + - not_null + + - name: INSERTED_TIMESTAMP + tests: + - not_null + + - name: MODIFIED_TIMESTAMP + tests: + - not_null diff --git a/models/silver/defi/silver__liquidity_pool_actions_arcane.sql b/models/silver/defi/silver__liquidity_pool_actions_arcane.sql index 85487b2..fe04bc9 100644 --- a/models/silver/defi/silver__liquidity_pool_actions_arcane.sql +++ b/models/silver/defi/silver__liquidity_pool_actions_arcane.sql @@ -1,73 +1,75 @@ {{ config( - materialized='incremental', - unique_key='liquidity_pool_actions_arcane_id', - incremental_strategy='merge', + materialized = 'incremental', + unique_key = 'liquidity_pool_actions_arcane_id', + incremental_strategy = 'merge', merge_exclude_columns = ['inserted_timestamp'], cluster_by = ['modified_timestamp::DATE'], - tags=['noncore', 'full_test'] + tags = ['noncore', 'full_test'] ) }} --- depends on: {{ ref('core__fact_transitions') }} -with -root_actions as ( - select +WITH root_actions AS ( + SELECT tx_id, program_id, function, - program_id || '/' || function as root_action, + program_id || '/' || function AS root_action, CASE WHEN function ILIKE '%add%' THEN 'Add' WHEN function ILIKE '%remove%' THEN 'Remove' ELSE 'OTHER' - END as liquidity_action - from - aleo.core.fact_transitions - where - program_id ilike 'arcn%' - and function ilike '%liq%' - and function not ilike '%credits%' + END AS liquidity_action + FROM + {{ ref('core__fact_transitions') }} + WHERE + program_id ILIKE 'arcn%' + AND function ILIKE '%liq%' + AND function NOT ILIKE '%credits%' ), -reports as ( - select + +reports AS ( + SELECT block_timestamp, block_id, tx_id, succeeded, INPUTS - from - aleo.core.fact_transitions - where - program_id ilike 'arcn%' - and function = 'report' + FROM + {{ ref('core__fact_transitions') }} + WHERE + program_id ILIKE 'arcn%' + AND function = 'report' ), -parsed as ( - select + +parsed AS ( + SELECT block_timestamp, block_id, tx_id, succeeded, root_action, liquidity_action, - inputs[1] :value :: string as liquidity_provider, - inputs[2] :value :: string as token1_id, - inputs[3] :value :: string as token2_id, - split_part(inputs[4] :value, 'u', 1) :: number as token1_amount, - split_part(inputs[5] :value, 'u', 1) :: number as token2_amount - from + inputs[1]:value::string AS liquidity_provider, + inputs[2]:value::string AS token1_id, + inputs[3]:value::string AS token2_id, + split_part(inputs[4]:value, 'u', 1)::number AS token1_amount, + split_part(inputs[5]:value, 'u', 1)::number AS token2_amount + FROM root_actions - join - reports using(tx_id) + JOIN + reports USING(tx_id) ), -tokens as ( - select + +tokens AS ( + SELECT token_id, name_encoded, token_name, decimals - from - aleo_dev.silver.token_registrations + FROM + {{ ref('silver__token_registrations') }} ) -select + +SELECT p.block_timestamp, p.block_id, p.tx_id, @@ -75,26 +77,26 @@ select p.root_action, p.liquidity_action, p.liquidity_provider, + p.token1_amount / power(10, COALESCE(t1.decimals, 6)) AS token1_amount, + CASE + WHEN p.token1_id = '3443843282313283355522573239085696902919850365217539366784739393210722344986field' THEN 'Aleo' + ELSE t1.token_name + END AS token1_name, p.token1_id, + p.token2_amount / power(10, COALESCE(t2.decimals, 6)) AS token2_amount, + CASE + WHEN p.token2_id = '3443843282313283355522573239085696902919850365217539366784739393210722344986field' THEN 'Aleo' + ELSE t2.token_name + END AS token2_name, p.token2_id, - case - when p.token1_id = '3443843282313283355522573239085696902919850365217539366784739393210722344986field' then 'Aleo' - else t1.token_name - end as token1_name, - case - when p.token2_id = '3443843282313283355522573239085696902919850365217539366784739393210722344986field' then 'Aleo' - else t2.token_name - end as token2_name, - p.token1_amount / power(10, coalesce(t1.decimals, 6)) as token1_amount, - p.token2_amount / power(10, coalesce(t2.decimals, 6)) as token2_amount, - {{ dbt_utils.generate_surrogate_key(['p.tx_id','p.token1_id', 'p.token2_id']) }} AS liquidity_pool_actions_arcane_id, - SYSDATE() as inserted_timestamp, - SYSDATE() as modified_timestamp, + {{ dbt_utils.generate_surrogate_key(['p.tx_id', 'p.token1_id', 'p.token2_id']) }} AS liquidity_pool_actions_arcane_id, + SYSDATE() AS inserted_timestamp, + SYSDATE() AS modified_timestamp, '{{ invocation_id }}' AS _invocation_id -from +FROM parsed p -left join {{ ref('silver__token_registrations') }} t1 on p.token1_id = t1.token_id -left join {{ ref('silver__token_registrations') }} t2 on p.token2_id = t2.token_id -qualify(ROW_NUMBER() over(PARTITION BY p.tx_id -ORDER BY - root_action) = 1) \ No newline at end of file +LEFT JOIN + {{ ref('silver__token_registrations') }} t1 ON p.token1_id = t1.token_id +LEFT JOIN + {{ ref('silver__token_registrations') }} t2 ON p.token2_id = t2.token_id +QUALIFY(ROW_NUMBER() OVER(PARTITION BY p.tx_id ORDER BY root_action) = 1) \ No newline at end of file diff --git a/models/silver/defi/silver__liquidity_pool_actions_arcane.yml b/models/silver/defi/silver__liquidity_pool_actions_arcane.yml index 5d77dfd..5e5bebb 100644 --- a/models/silver/defi/silver__liquidity_pool_actions_arcane.yml +++ b/models/silver/defi/silver__liquidity_pool_actions_arcane.yml @@ -36,11 +36,7 @@ models: tests: - not_null - - name: token1_id - tests: - - not_null - - - name: token2_id + - name: token1_amount tests: - not_null @@ -48,11 +44,7 @@ models: tests: - not_null - - name: token2_name - tests: - - not_null - - - name: token1_amount + - name: token1_id tests: - not_null @@ -60,6 +52,14 @@ models: tests: - not_null + - name: token2_name + tests: + - not_null + + - name: token2_id + tests: + - not_null + - name: inserted_timestamp tests: - not_null diff --git a/models/silver/defi/silver__swaps_arcane.sql b/models/silver/defi/silver__swaps_arcane.sql index 0a3d164..d94872c 100644 --- a/models/silver/defi/silver__swaps_arcane.sql +++ b/models/silver/defi/silver__swaps_arcane.sql @@ -1,117 +1,110 @@ {{ config( - materialized='incremental', - unique_key='swaps_arcane_id', - incremental_strategy='merge', + materialized = 'incremental', + unique_key = 'swaps_arcane_id', + incremental_strategy = 'merge', merge_exclude_columns = ['inserted_timestamp'], - cluster_by = ['modified_timestamp::DATE', 'swapper','swap_from_name', 'swap_to_name'], - tags=['noncore', 'full_test'] + cluster_by = ['modified_timestamp::DATE', 'swapper', 'swap_from_name', 'swap_to_name'], + tags = ['noncore', 'full_test'] ) }} --- depends on: {{ ref('core__fact_transitions') }} -with -root_actions as ( - select +WITH root_actions AS ( + SELECT tx_id, - program_id || '/' || function as root_action - from + program_id || '/' || function AS root_action + FROM {{ ref('core__fact_transitions') }} - where - program_id ilike 'arcn%' - and function ilike '%swap%' + WHERE + program_id ILIKE 'arcn%' + AND function ILIKE '%swap%' {% if is_incremental() %} - and - modified_timestamp >= ( - select - MAX( - modified_timestamp - ) - from + AND modified_timestamp >= ( + SELECT + MAX(modified_timestamp) + FROM {{ this }} ) {% endif %} - QUALIFY ROW_NUMBER() OVER ( - PARTITION BY tx_id - ORDER BY index DESC - ) = 1 + QUALIFY ROW_NUMBER() OVER (PARTITION BY tx_id ORDER BY index DESC) = 1 ), -reports as ( - select + +reports AS ( + SELECT block_timestamp, block_id, tx_id, succeeded, - replace(inputs[0] :value, 'field', '') as address_from, - replace(inputs[1] :value, 'field', '') as address_to, - replace(inputs[2] :value, 'field', '') as swap_from, - replace(inputs[3] :value, 'field', '') as swap_to, - replace(inputs[4] :value, 'u128', '') as amount_from, - replace(inputs[5] :value, 'u128', '') as amount_to - from + REPLACE(inputs[0]:value, 'field', '') AS address_from, + REPLACE(inputs[1]:value, 'field', '') AS address_to, + inputs[2]:value AS swap_from, + inputs[3]:value AS swap_to, + REPLACE(inputs[4]:value, 'u128', '') AS amount_from, + REPLACE(inputs[5]:value, 'u128', '') AS amount_to + FROM aleo.core.fact_transitions - where + WHERE program_id = 'arcn_compliance_v1.aleo' - and function = 'report' + AND function = 'report' {% if is_incremental() %} - AND - modified_timestamp >= ( + AND modified_timestamp >= ( SELECT - MAX( - modified_timestamp - ) + MAX(modified_timestamp) FROM {{ this }} ) {% endif %} ), -agg as ( -select - block_timestamp, - block_id, - tx_id, - succeeded, - root_action, - address_from, - address_to, - CASE - WHEN swap_from = '3443843282313283355522573239085696902919850365217539366784739393210722344986' THEN 'Aleo' - ELSE swap_from - END as swap_from, - CASE - WHEN swap_to = '3443843282313283355522573239085696902919850365217539366784739393210722344986' THEN 'Aleo' - ELSE swap_to - END as swap_to, - amount_from :: number as amount_from, - amount_to :: number as amount_to -from - reports -join - root_actions using(tx_id) + +agg AS ( + SELECT + block_timestamp, + block_id, + tx_id, + succeeded, + root_action, + address_from, + address_to, + CASE + WHEN swap_from = '3443843282313283355522573239085696902919850365217539366784739393210722344986field' THEN 'Aleo' + ELSE swap_from + END AS swap_from, + CASE + WHEN swap_to = '3443843282313283355522573239085696902919850365217539366784739393210722344986field' THEN 'Aleo' + ELSE swap_to + END AS swap_to, + amount_from::number AS amount_from, + amount_to::number AS amount_to + FROM + reports + JOIN + root_actions USING(tx_id) ) -select +SELECT a.block_timestamp, a.block_id, a.tx_id, a.succeeded, - a.address_from as swapper, - a.amount_from / power(10, coalesce(b.decimals, 6)) as swap_from_amount, - coalesce(b.token_name, a.swap_from) as swap_from_name, - case - when b.token_id is null then '3443843282313283355522573239085696902919850365217539366784739393210722344986' - else b.token_id - end as swap_from_id, - a.amount_to / power(10, coalesce(c.decimals, 6)) as swap_to_amount, - coalesce(c.token_name, a.swap_to) as swap_to_name, - case - when c.token_id is null then '3443843282313283355522573239085696902919850365217539366784739393210722344986' - else c.token_id - end as swap_to_id, + a.address_from AS swapper, + a.amount_from / power(10, COALESCE(b.decimals, 6)) AS swap_from_amount, + COALESCE(b.token_name, a.swap_from) AS swap_from_name, + CASE + WHEN b.token_id IS NULL THEN '3443843282313283355522573239085696902919850365217539366784739393210722344986field' + ELSE b.token_id + END AS swap_from_id, + a.amount_to / power(10, COALESCE(c.decimals, 6)) AS swap_to_amount, + COALESCE(c.token_name, a.swap_to) AS swap_to_name, + CASE + WHEN c.token_id IS NULL THEN '3443843282313283355522573239085696902919850365217539366784739393210722344986field' + ELSE c.token_id + END AS swap_to_id, root_action, - {{ dbt_utils.generate_surrogate_key(['a.tx_id','b.token_id']) }} AS swaps_arcane_id, + {{ dbt_utils.generate_surrogate_key(['a.tx_id', 'b.token_id']) }} AS swaps_arcane_id, SYSDATE() AS inserted_timestamp, SYSDATE() AS modified_timestamp, '{{ invocation_id }}' AS _invocation_id -from +FROM agg a - left join {{ ref('silver__token_registrations') }} b on a.swap_from = b.token_id - left join {{ ref('silver__token_registrations') }} c on a.swap_to = c.token_id \ No newline at end of file +LEFT JOIN + {{ ref('silver__token_registrations') }} b ON a.swap_from = b.token_id +LEFT JOIN + {{ ref('silver__token_registrations') }} c ON a.swap_to = c.token_id \ No newline at end of file diff --git a/models/silver/defi/silver__swaps_arcane.yml b/models/silver/defi/silver__swaps_arcane.yml index 7cb0baa..b061538 100644 --- a/models/silver/defi/silver__swaps_arcane.yml +++ b/models/silver/defi/silver__swaps_arcane.yml @@ -32,7 +32,11 @@ models: tests: - not_null - - name: swap_from + - name: swap_from_name + tests: + - not_null + + - name: swap_from_id tests: - not_null @@ -40,7 +44,11 @@ models: tests: - not_null - - name: swap_to + - name: swap_to_name + tests: + - not_null + + - name: swap_to_id tests: - not_null diff --git a/models/silver/core/tokens/silver__token_registrations.sql b/models/silver/tokens/silver__token_registrations.sql similarity index 87% rename from models/silver/core/tokens/silver__token_registrations.sql rename to models/silver/tokens/silver__token_registrations.sql index ab650fb..03a0149 100644 --- a/models/silver/core/tokens/silver__token_registrations.sql +++ b/models/silver/tokens/silver__token_registrations.sql @@ -1,5 +1,5 @@ {{ config( - materialized = 'table', + materialized = 'view', tags = ['core', 'full_test'] ) }} @@ -65,7 +65,7 @@ cleaned_strings as ( tx_id, block_id, block_timestamp, - split_part(token_id_raw, 'field', 1) as token_id, + token_id_raw as token_id, split_part(name_raw, 'u', 1) as name_encoded, split_part(symbol_raw, 'u', 1) as symbol_encoded, split_part(decimals_raw, 'u', 1) as decimals, @@ -76,12 +76,12 @@ cleaned_strings as ( parsed_inputs ) select - tx_id, - block_id, - block_timestamp, + tx_id as tx_id_created, + block_id as block_id_created, + block_timestamp as block_timestamp_created, token_id, - udf_hex_to_string(substr(utils.udf_int_to_hex(name_encoded), 3)) as token_name, - udf_hex_to_string(substr(udf_int_to_hex(symbol_encoded), 3)) as symbol, + utils.udf_hex_to_string(substr(utils.udf_int_to_hex(name_encoded), 3)) as token_name, + utils.udf_hex_to_string(substr(utils.udf_int_to_hex(symbol_encoded), 3)) as symbol, decimals, max_supply, external_auth_required, @@ -89,9 +89,10 @@ select name_encoded, symbol_encoded, {{ dbt_utils.generate_surrogate_key( - ['tx_id', 'token_name'] + ['token_id'] ) }} AS tokens_id, SYSDATE() as inserted_timestamp, SYSDATE() as modified_timestamp, '{{ invocation_id }}' AS _invocation_id -from cleaned_strings +from + cleaned_strings diff --git a/models/silver/core/tokens/silver__token_registrations.yml b/models/silver/tokens/silver__token_registrations.yml similarity index 81% rename from models/silver/core/tokens/silver__token_registrations.yml rename to models/silver/tokens/silver__token_registrations.yml index 7debf97..52f4c7f 100644 --- a/models/silver/core/tokens/silver__token_registrations.yml +++ b/models/silver/tokens/silver__token_registrations.yml @@ -4,15 +4,15 @@ models: - name: silver__token_registrations columns: - - name: tx_id + - name: tx_id_created tests: - not_null - - name: block_id + - name: block_id_created tests: - not_null - - name: block_timestamp + - name: block_timestamp_created tests: - not_null @@ -21,12 +21,8 @@ models: - not_null - name: token_name - tests: - - not_null - name: symbol - tests: - - not_null - name: decimals tests: