diff --git a/models/gold/rewards/rewards__fact_points_transfers.sql b/models/gold/rewards/rewards__fact_points_transfers.sql index 85bbaf6..bceaaf2 100644 --- a/models/gold/rewards/rewards__fact_points_transfers.sql +++ b/models/gold/rewards/rewards__fact_points_transfers.sql @@ -1,11 +1,72 @@ {{ config( materialized = 'view', - meta ={ 'database_tags':{ 'table':{ 'PURPOSE': 'REWARDS' }} }, tags = ['scheduled_non_core'] ) }} -SELECT - batch_id, +WITH legacy AS ( + SELECT + batch_id AS point_id, + created_at, + batch_index, + transfer_index, + from_address, + to_address, + boxes, + keys, + points, + NULL AS direction, + NULL AS amount_start, + NULL AS amount_end, + NULL AS account_id, + NULL AS user_id, + from_address AS user_wallet_address, + NULL AS transaction_id, + NULL AS data, + NULL AS partition_key, + NULL AS index, + NULL AS _inserted_timestamp, + points_transfers_id AS fact_points_transfers_id, + request_date, + inserted_timestamp, + modified_timestamp, + 'legacy' AS source + FROM + {{ ref('silver_api__points_transfers') }} +), + +new_data AS ( + SELECT + entry_id AS point_id, + created_at, + INDEX AS batch_index, + NULL AS transfer_index, + user_wallet_address AS from_address, + NULL AS to_address, + NULL AS boxes, + NULL AS keys, + amount AS points, + direction, + amount_start, + amount_end, + account_id, + user_id, + user_wallet_address, + transaction_id, + data, + partition_key, + INDEX AS index, + _inserted_timestamp, + reward_points_spend_id AS fact_points_transfers_id, + DATE_TRUNC('day', created_at) AS request_date, + inserted_timestamp, + modified_timestamp, + 'snag' AS source + FROM + {{ ref('silver_api__reward_points_spend') }} +), +FINAL AS (SELECT + point_id, + source, created_at, batch_index, transfer_index, @@ -14,9 +75,48 @@ SELECT boxes, keys, points, - points_transfers_id AS fact_points_transfers_id, - request_date, - inserted_timestamp, - modified_timestamp -FROM - {{ ref('silver_api__points_transfers') }} + direction, + amount_start, + amount_end, + account_id, + user_id, + user_wallet_address, + transaction_id, + data, + partition_key, + index, + _inserted_timestamp +FROM legacy +UNION ALL +SELECT + point_id, + source, + created_at, + batch_index, + transfer_index, + from_address, + to_address, + boxes, + keys, + points, + direction, + amount_start, + amount_end, + account_id, + user_id, + user_wallet_address, + transaction_id, + data, + partition_key, + index, + _inserted_timestamp +FROM new_data +) + +SELECT + *, + {{ dbt_utils.generate_surrogate_key(['point_id', 'source', 'created_at', 'batch_index', 'transfer_index']) }} AS fact_points_transfers_id, + SYSDATE() AS inserted_timestamp, + SYSDATE() AS modified_timestamp, + '{{ invocation_id }}' AS _invocation_id +FROM FINAL \ No newline at end of file diff --git a/models/gold/rewards/rewards__fact_points_transfers.yml b/models/gold/rewards/rewards__fact_points_transfers.yml index 8e80e8f..076f292 100644 --- a/models/gold/rewards/rewards__fact_points_transfers.yml +++ b/models/gold/rewards/rewards__fact_points_transfers.yml @@ -2,19 +2,41 @@ version: 2 models: - name: rewards__fact_points_transfers - description: '{{ doc("rewards__fact_points_transfers") }}' + description: | + Unified rewards points transfer table combining legacy Flow Points API + and new Snag Loyalty API data. + + **Data Sources:** + - **Legacy** (source='legacy'): Oct 2024 - Apr 14, 2025 from Flow Points API + - **Snag** (source='snag'): Apr 16, 2025 onwards from Snag Loyalty API + tests: - dbt_utils.recency: datepart: day - field: request_date - interval: 1 + field: created_at + interval: 2 severity: warn columns: - - name: BATCH_ID - description: "The batch ID of the transfer" + - name: POINT_ID + description: "Unique identifier for the points transaction (batch_id for legacy, entry_id for snag)" tests: - not_null + - dbt_expectations.expect_column_values_to_be_in_type_list: + column_type_list: + - STRING + - VARCHAR + + - name: SOURCE + description: "Data source indicator: 'legacy' for Flow Points API or 'snag' for Snag Loyalty API" + tests: + - not_null + - accepted_values: + values: ['legacy', 'snag'] + - dbt_expectations.expect_column_values_to_be_in_type_list: + column_type_list: + - STRING + - VARCHAR - name: CREATED_AT description: "The date of the transfer" @@ -22,51 +44,84 @@ models: - not_null - name: BATCH_INDEX - description: "The index of the batch for the sending account" + description: "Index of the batch (legacy) or transaction entry (snag)" tests: - not_null - name: TRANSFER_INDEX - description: "The index of the transfer within the batch" - tests: - - not_null + description: "Legacy only: Index of the individual transfer within a batch. NULL for snag data." - name: FROM_ADDRESS - description: "The EVM address of the sender" - tests: - - not_null + description: "EVM address of the user involved in the transaction" - name: TO_ADDRESS - description: "The EVM address of the recipient" - tests: - - not_null + description: "Legacy only: EVM address of the recipient. NULL for snag data." - name: BOXES - description: "The number of boxes transferred" - tests: - - not_null + description: "Legacy only: Number of boxes transferred. NULL for snag data." - name: KEYS - description: "The number of keys transferred" - tests: - - not_null + description: "Legacy only: Number of keys transferred. NULL for snag data." - name: POINTS - description: "The number of points transferred" + description: "Number of points involved in the transaction" + + - name: DIRECTION + description: "Snag only: Transaction direction - 'credit' for points earned or 'debit' for points spent. NULL for legacy data." + tests: + - not_null: + where: source = 'snag' + + - name: AMOUNT_START + description: "Snag only: Loyalty account balance before the transaction. NULL for legacy data." + tests: + - not_null: + where: source = 'snag' + + - name: AMOUNT_END + description: "Snag only: Loyalty account balance after the transaction. NULL for legacy data." + tests: + - not_null: + where: source = 'snag' + + - name: ACCOUNT_ID + description: "Snag only: Loyalty account identifier. NULL for legacy data." + tests: + - not_null: + where: source = 'snag' + + - name: USER_ID + description: "Snag only: User identifier associated with the loyalty account. NULL for legacy data." + + - name: USER_WALLET_ADDRESS + description: "EVM wallet address of the user (maps from from_address for legacy, native field for snag)" + + - name: TRANSACTION_ID + description: "Snag only: Parent loyalty transaction identifier. NULL for legacy data." + + - name: DATA + description: "Snag only: Full raw JSON response from the API. NULL for legacy data." + + - name: PARTITION_KEY + description: "Snag only: Partition key for efficient querying. NULL for legacy data." + + - name: INDEX + description: "Snag only: Index of the transaction entry within the partition. NULL for legacy data." + + - name: _INSERTED_TIMESTAMP + description: "Snag only: Timestamp when the record was inserted into the warehouse. NULL for legacy data." - name: FACT_POINTS_TRANSFERS_ID + description: "Surrogate primary key for the table" tests: - not_null - unique - name: REQUEST_DATE - tests: - - not_null + description: "Date of the points transfer (truncated to day)" - name: INSERTED_TIMESTAMP - tests: - - not_null + description: "UTC timestamp when the record was first inserted into this table" - name: MODIFIED_TIMESTAMP - tests: - - not_null + description: "UTC timestamp when this record was last modified" diff --git a/models/gold/rewards/rewards__fact_transaction_entries.sql b/models/gold/rewards/rewards__fact_transaction_entries.sql index 3bb9d43..681e87f 100644 --- a/models/gold/rewards/rewards__fact_transaction_entries.sql +++ b/models/gold/rewards/rewards__fact_transaction_entries.sql @@ -1,6 +1,5 @@ {{ config( - materialized = 'view', - tags = ['streamline_non_core'] + enabled = false )}} SELECT