diff --git a/models/oklink/gold/oklink__active_users.sql b/models/oklink/gold/oklink__active_users.sql index cc3163f..d2b5cef 100644 --- a/models/oklink/gold/oklink__active_users.sql +++ b/models/oklink/gold/oklink__active_users.sql @@ -1,148 +1,53 @@ +-- depends_on: {{ ref('bronze__oklink') }} {{ config( materialized = 'incremental', - unique_key = 'active_users_id', + unique_key = ['as_of_date', 'blockchain'], tags = ['oklink'] ) }} WITH source AS ( + SELECT - date_day::DATE AS as_of_date, + date_day :: DATE AS as_of_date, blockchain, - data, - TRY_TO_NUMBER(data:data[0]:activeAddresses::STRING) AS active_addresses, - TRY_TO_NUMBER(data:data[0]:newActiveAddresses::STRING) AS active_addresses_change, + TRY_CAST( + DATA :data [0] :activeAddresses :: STRING AS INT + ) AS active_users, _inserted_timestamp FROM {% if is_incremental() %} - {{ ref("bronze__oklink") }} +{{ ref("bronze__oklink") }} {% else %} {{ ref("bronze__oklink_FR") }} {% endif %} - - WHERE - metric = 'address' - AND data:code = '0' - AND data:data[0]:activeAddresses IS NOT NULL - AND TRY_TO_NUMBER(data:data[0]:activeAddresses::STRING) > 0 -), +WHERE + metric = 'address' + AND active_users IS NOT NULL {% if is_incremental() %} -prev_data AS ( - -- Get all existing data to ensure complete history +AND _inserted_timestamp > ( SELECT - blockchain, - as_of_date, - active_users, - active_users_change, - active_users_reported, - _inserted_timestamp - FROM {{ this }} -), -combined_data AS ( - -- New data from API - SELECT - s.blockchain, - s.as_of_date, - s.active_addresses AS active_users_reported, - s.active_addresses_change AS active_users_change, - s._inserted_timestamp, - TRUE AS is_new_data - FROM source s - - UNION ALL - - SELECT - p.blockchain, - p.as_of_date, - p.active_users_reported, - p.active_users_change, - p._inserted_timestamp, - FALSE AS is_new_data - FROM prev_data p - WHERE NOT EXISTS ( - SELECT 1 - FROM source s - WHERE s.blockchain = p.blockchain - AND s.as_of_date = p.as_of_date - ) -), - -{% else %} -combined_data AS ( - -- Initial load/non-incremental - just use source data - SELECT - blockchain, - as_of_date, - active_addresses AS active_users_reported, - active_addresses_change AS active_users_change, - _inserted_timestamp, - TRUE AS is_new_data - FROM source -), -{% endif %} - -blockchain_first_date AS ( - SELECT - blockchain, - MIN(as_of_date) AS first_date - FROM combined_data - GROUP BY 1 -), -calculations AS ( - SELECT - cd.blockchain, - cd.as_of_date, - cd.active_users_reported, - COALESCE(cd.active_users_change, 0) AS active_users_change, - cd._inserted_timestamp, - cd.is_new_data, - bfd.first_date, - CASE WHEN cd.as_of_date = bfd.first_date THEN cd.active_users_reported ELSE NULL END AS base_value + MAX(_inserted_timestamp) FROM - combined_data cd - JOIN blockchain_first_date bfd - ON cd.blockchain = bfd.blockchain -), -final AS ( - SELECT - blockchain, - as_of_date, - active_users_reported, - active_users_change, - _inserted_timestamp, - -- Calculate our own cumulative value: starting with base_value on first date -> add the changes to running sum - SUM(COALESCE(base_value, 0)) OVER ( - PARTITION BY blockchain - ORDER BY as_of_date - ROWS UNBOUNDED PRECEDING - ) + - -- Add all changes except on the first day (since base_value includes all previous activity) - SUM(CASE WHEN base_value IS NULL THEN active_users_change ELSE 0 END) OVER ( - PARTITION BY blockchain - ORDER BY as_of_date - ROWS UNBOUNDED PRECEDING - ) AS active_users - FROM calculations -) - + {{ this }} +) +{% endif %} +) SELECT blockchain, 'active_users' AS metric, + 'The reported number of activeAddresses as of the as_of_date' AS description, as_of_date, active_users, - active_users_change, - active_users_reported, _inserted_timestamp, {{ dbt_utils.generate_surrogate_key(['blockchain', 'metric', 'as_of_date']) }} AS active_users_id, SYSDATE() AS inserted_timestamp, - SYSDATE() AS modified_timestamp, - '{{ invocation_id }}' AS _invocation_id -FROM - final -QUALIFY ROW_NUMBER() -OVER ( - PARTITION BY - blockchain, as_of_date - ORDER BY - _inserted_timestamp DESC NULLS LAST) = 1 \ No newline at end of file + SYSDATE() AS modified_timestamp +FROM + source qualify ROW_NUMBER() over ( + PARTITION BY blockchain, + as_of_date + ORDER BY + _inserted_timestamp DESC nulls last + ) = 1 diff --git a/models/oklink/gold/oklink__active_users.yml b/models/oklink/gold/oklink__active_users.yml index 371cd6b..ce133c4 100644 --- a/models/oklink/gold/oklink__active_users.yml +++ b/models/oklink/gold/oklink__active_users.yml @@ -11,8 +11,8 @@ models: - not_null - name: METRIC description: "The metric name is always set as 'active_users'" - tests: - - not_null + - name: DESCRIPTION + description: "The metric description" - name: AS_OF_DATE description: "The date as of which the active users are counted." tests: diff --git a/models/oklink/gold/oklink__contracts.sql b/models/oklink/gold/oklink__contracts.sql new file mode 100644 index 0000000..2dee209 --- /dev/null +++ b/models/oklink/gold/oklink__contracts.sql @@ -0,0 +1,53 @@ +-- depends_on: {{ ref('bronze__oklink') }} +{{ config( + materialized = 'incremental', + unique_key = ['as_of_date', 'blockchain'], + tags = ['oklink'] +) }} + +WITH source AS ( + + SELECT + date_day :: DATE AS as_of_date, + blockchain, + TRY_CAST( + DATA :data [0] :contractAddresses :: STRING AS INT + ) AS contract_count, + _inserted_timestamp + FROM + +{% if is_incremental() %} +{{ ref("bronze__oklink") }} +{% else %} + {{ ref("bronze__oklink_FR") }} +{% endif %} +WHERE + metric = 'address' + AND contract_count IS NOT NULL + +{% if is_incremental() %} +AND _inserted_timestamp > ( + SELECT + MAX(_inserted_timestamp) + FROM + {{ this }} +) +{% endif %} +) +SELECT + blockchain, + 'contract_count' AS metric, + 'The reported number of contractAddresses as of the as_of_date' AS description, + as_of_date, + contract_count, + _inserted_timestamp, + {{ dbt_utils.generate_surrogate_key(['blockchain', 'metric', 'as_of_date']) }} AS contracts_id, + SYSDATE() AS inserted_timestamp, + SYSDATE() AS modified_timestamp +FROM + source qualify ROW_NUMBER() over ( + PARTITION BY blockchain, + as_of_date + ORDER BY + _inserted_timestamp DESC nulls last + ) = 1 diff --git a/models/oklink/gold/oklink__contracts.yml b/models/oklink/gold/oklink__contracts.yml new file mode 100644 index 0000000..25c2a43 --- /dev/null +++ b/models/oklink/gold/oklink__contracts.yml @@ -0,0 +1,30 @@ +version: 2 + +models: + - name: oklink__contracts + description: "This model returns the total deployed contracts for each blockchain from as of date." + + columns: + - name: BLOCKCHAIN + description: "The blockchain where metric is from." + tests: + - not_null + - name: METRIC + description: "The metric name is always set as 'contract_count'" + - name: DESCRIPTION + description: "The metric description" + - name: AS_OF_DATE + description: "The date as of which the active users are counted." + tests: + - not_null + - dbt_expectations.expect_row_values_to_have_recent_data: + datepart: day + interval: 2 + - name: CONTRACT_COUNT + description: "The number of deployed contracts for the given blockchain and as of date." + tests: + - not_null + - name: CONTRACTS_ID + description: "The surrogate key for the contracts" + tests: + - unique \ No newline at end of file diff --git a/models/oklink/gold/oklink__tam.sql b/models/oklink/gold/oklink__tam.sql new file mode 100644 index 0000000..9343113 --- /dev/null +++ b/models/oklink/gold/oklink__tam.sql @@ -0,0 +1,53 @@ +-- depends_on: {{ ref('bronze__oklink') }} +{{ config( + materialized = 'incremental', + unique_key = ['as_of_date', 'blockchain'], + tags = ['oklink'] +) }} + +WITH source AS ( + + SELECT + date_day :: DATE AS as_of_date, + blockchain, + TRY_CAST( + DATA :data [0] :totalAddresses :: STRING AS INT + ) AS total_addresses, + _inserted_timestamp + FROM + +{% if is_incremental() %} +{{ ref("bronze__oklink") }} +{% else %} + {{ ref("bronze__oklink_FR") }} +{% endif %} +WHERE + metric = 'address' + AND total_addresses IS NOT NULL + +{% if is_incremental() %} +AND _inserted_timestamp > ( + SELECT + MAX(_inserted_timestamp) + FROM + {{ this }} +) +{% endif %} +) +SELECT + blockchain, + 'tam' AS metric, + 'The reported number of total_addresses as of the as_of_date' AS description, + as_of_date, + total_addresses, + _inserted_timestamp, + {{ dbt_utils.generate_surrogate_key(['blockchain', 'metric', 'as_of_date']) }} AS tam_id, + SYSDATE() AS inserted_timestamp, + SYSDATE() AS modified_timestamp +FROM + source qualify ROW_NUMBER() over ( + PARTITION BY blockchain, + as_of_date + ORDER BY + _inserted_timestamp DESC nulls last + ) = 1 diff --git a/models/oklink/gold/oklink__tam.yml b/models/oklink/gold/oklink__tam.yml new file mode 100644 index 0000000..b9912e7 --- /dev/null +++ b/models/oklink/gold/oklink__tam.yml @@ -0,0 +1,30 @@ +version: 2 + +models: + - name: oklink__tam + description: "This model returns the total addressable market for each blockchain from as of date." + + columns: + - name: BLOCKCHAIN + description: "The blockchain where tam is counted from." + tests: + - not_null + - name: METRIC + description: "The metric name is always set as 'tam'" + - name: DESCRIPTION + description: "The metric description" + - name: AS_OF_DATE + description: "The date as of which the tam is counted." + tests: + - not_null + - dbt_expectations.expect_row_values_to_have_recent_data: + datepart: day + interval: 2 + - name: TOTAL_ADDRESSES + description: "The number of addresses for the given blockchain and as of date." + tests: + - not_null + - name: TAM_ID + description: "The surrogate key for the tam" + tests: + - unique \ No newline at end of file diff --git a/models/oklink/gold/oklink__tx_count.sql b/models/oklink/gold/oklink__tx_count.sql index 2cd4fd8..539c7fb 100644 --- a/models/oklink/gold/oklink__tx_count.sql +++ b/models/oklink/gold/oklink__tx_count.sql @@ -1,62 +1,67 @@ +-- depends_on: {{ ref('bronze__oklink') }} {{ config( materialized = "incremental", - unique_key = ["tx_count_id"], + unique_key = ['block_date', 'blockchain'], tags = ['oklink'] ) }} WITH source_data AS ( + SELECT - date_day::DATE AS as_of_date, + date_day :: DATE AS as_of_date, blockchain, - data, + DATA, _inserted_timestamp FROM - -{% if is_incremental() %} - {{ ref("bronze_oklink") }} -{% else %} - {{ ref("bronze_oklink_FR") }} -{% endif %} - WHERE - metric = 'stats' - AND data:code = '0' - {% if is_incremental() %} - AND _inserted_timestamp >= ( - SELECT - MAX(_inserted_timestamp) - FROM - {{ this }} - ) +{{ ref("bronze__oklink") }} +{% else %} + {{ ref("bronze__oklink_FR") }} +{% endif %} +WHERE + metric = 'stats' + AND DATA :code = '0' + +{% if is_incremental() %} +AND _inserted_timestamp >= ( + SELECT + MAX(_inserted_timestamp) + FROM + {{ this }} +) {% endif %} ), flattened_data AS ( SELECT as_of_date, blockchain, - TRY_TO_NUMBER(stats.value:totalTransactionCount) AS tx_count + _inserted_timestamp, + TRY_CAST( + stats.value :totalTransactionCount :: STRING AS INT + ) AS tx_count FROM source_data, - LATERAL FLATTEN(input => data:data[0]:statsHistoryList) as stats + LATERAL FLATTEN( + input => DATA :data [0] :statsHistoryList + ) AS stats WHERE - stats.value:totalTransactionCount IS NOT NULL - AND TRY_TO_NUMBER(stats.value:totalTransactionCount) > 0 + tx_count IS NOT NULL ) - SELECT blockchain, 'tx_count' AS metric, + 'The reported number of totalTransactionCount on the as_of_date' AS description, + as_of_date AS block_date, tx_count, _inserted_timestamp, - {{ dbt_utils.generate_surrogate_key(['blockchain', 'metric', 'as_of_date']) }} AS tx_count_id, + {{ dbt_utils.generate_surrogate_key(['blockchain', 'metric', 'block_date']) }} AS tx_count_id, SYSDATE() AS inserted_timestamp, SYSDATE() AS modified_timestamp, '{{ invocation_id }}' AS _invocation_id -FROM flattened_data -QUALIFY ROW_NUMBER() -OVER ( - PARTITION BY - tx_count_id - ORDER BY - _inserted_timestamp DESC) = 1 \ No newline at end of file +FROM + flattened_data qualify ROW_NUMBER() over ( + PARTITION BY tx_count_id + ORDER BY + _inserted_timestamp DESC + ) = 1 diff --git a/models/oklink/gold/oklink__tx_count.yml b/models/oklink/gold/oklink__tx_count.yml index 66266d4..10b8873 100644 --- a/models/oklink/gold/oklink__tx_count.yml +++ b/models/oklink/gold/oklink__tx_count.yml @@ -2,7 +2,7 @@ version: 2 models: - name: oklink__tx_count - description: "This model returns the tx count for each blockchain for the last 24 hours from the as of date." + description: "This model returns the number of transactions for each blockchain and block date" columns: - name: BLOCKCHAIN @@ -11,9 +11,9 @@ models: - not_null - name: METRIC description: "The metric name is always set as 'tx_count'" - tests: - - not_null - - name: AS_OF_DATE + - name: DESCRIPTION + description: "The metric description" + - name: BLOCK_DATE description: "The date as of which the tx count is counted." tests: - not_null