diff --git a/models/descriptions/daily_active_contracts.md b/models/descriptions/daily_active_contracts.md new file mode 100644 index 0000000..72a391e --- /dev/null +++ b/models/descriptions/daily_active_contracts.md @@ -0,0 +1,5 @@ +{% docs daily_active_contracts %} + +The daily number of active contracts. + +{% enddocs %} diff --git a/models/descriptions/monthly_active_contracts.md b/models/descriptions/monthly_active_contracts.md new file mode 100644 index 0000000..2474884 --- /dev/null +++ b/models/descriptions/monthly_active_contracts.md @@ -0,0 +1,5 @@ +{% docs monthly_active_contracts %} + +The number of active contracts for the month of the date. + +{% enddocs %} diff --git a/models/descriptions/weekly_active_contracts.md b/models/descriptions/weekly_active_contracts.md new file mode 100644 index 0000000..549c695 --- /dev/null +++ b/models/descriptions/weekly_active_contracts.md @@ -0,0 +1,5 @@ +{% docs weekly_active_contracts %} + +The number of active contracts for the week of the date. + +{% enddocs %} diff --git a/models/metrics/metrics__active_contracts.sql b/models/metrics/metrics__active_contracts.sql new file mode 100644 index 0000000..7a7ee46 --- /dev/null +++ b/models/metrics/metrics__active_contracts.sql @@ -0,0 +1,85 @@ +{{ config( + materialized = 'incremental', + incremental_strategy = 'delete+insert', + tags = ['metrics'], + cluster_by = ['date'] +) }} + +WITH txs AS ( + + SELECT + t.block_timestamp :: DATE AS DATE, + t.tx_receiver + FROM + {{ ref('silver__transactions') }} + t + JOIN {{ ref('silver__actions_events_function_call') }} + aefc + ON t.tx_hash = aefc.tx_hash + WHERE + 1 = 1 + +{% if is_incremental() %} +AND {{ incremental_last_x_days( + "t._inserted_timestamp", + 2 +) }} +{% endif %} +), +daily AS ( + SELECT + txs.date, + COUNT( + DISTINCT tx_receiver + ) AS daily_active_contracts + FROM + txs + GROUP BY + 1 +), +weekly AS ( + SELECT + DATE_TRUNC( + 'week', + txs.date + ) :: DATE AS week, + COUNT( + DISTINCT tx_receiver + ) AS weekly_active_contracts + FROM + txs + GROUP BY + 1 +), +monthly AS ( + SELECT + DATE_TRUNC( + 'month', + txs.date + ) :: DATE AS MONTH, + COUNT( + DISTINCT tx_receiver + ) AS montlhy_active_contracts + FROM + txs + GROUP BY + 1 +) +SELECT + daily.*, + weekly_active_contracts, + montlhy_active_contracts +FROM + daily + LEFT JOIN weekly + ON weekly.week = DATE_TRUNC( + 'week', + daily.date + ) :: DATE + LEFT JOIN monthly + ON monthly.month = DATE_TRUNC( + 'month', + daily.date + ) :: DATE +ORDER BY + 1 diff --git a/models/metrics/metrics__active_contracts.yml b/models/metrics/metrics__active_contracts.yml new file mode 100644 index 0000000..3a0b37e --- /dev/null +++ b/models/metrics/metrics__active_contracts.yml @@ -0,0 +1,40 @@ +version: 2 + +models: + - name: metrics__active_contracts + description: "Daily, weekly, and monthly active contracts on NEAR." + + columns: + - name: DATE + description: "{{ doc('date')}}" + tests: + - not_null + - dbt_expectations.expect_column_values_to_be_in_type_list: + column_type_list: + - TIMESTAMP_NTZ + + - name: DAILY_ACTIVE_CONTRACTS + description: "{{ doc('daily_active_contracts')}}" + tests: + - not_null + - dbt_expectations.expect_column_values_to_be_in_type_list: + column_type_list: + - NUMBER + - FLOAT + + - name: WEEKLY_ACTIVE_CONTRACTS + description: "{{ doc('weekly_active_contracts')}}" + tests: + - not_null + - dbt_expectations.expect_column_values_to_be_in_type_list: + column_type_list: + - NUMBER + - FLOAT + + - name: MONTHLY_ACTIVE_CONTRACTS + description: "{{ doc('monthly_active_contracts')}}" + tests: + - dbt_expectations.expect_column_values_to_be_in_type_list: + column_type_list: + - NUMBER + - FLOAT