diff --git a/models/gold/nft/nft__ez_nft_sales.yml b/models/gold/nft/nft__ez_nft_sales.yml index e93161b8..8386d55e 100644 --- a/models/gold/nft/nft__ez_nft_sales.yml +++ b/models/gold/nft/nft__ez_nft_sales.yml @@ -1,7 +1,7 @@ version: 2 models: - name: nft__ez_nft_sales - description: 'This table contains NFT sale events on the Optimism blockchain which includes Quixotic and Opensea.' + description: 'This table contains NFT sale events on the Optimism blockchain which includes Quixotic, Opensea and Element.' columns: - name: BLOCK_NUMBER diff --git a/models/silver/nft/sales/silver__complete_nft_sales.sql b/models/silver/nft/sales/silver__complete_nft_sales.sql index 656cb710..73fae264 100644 --- a/models/silver/nft/sales/silver__complete_nft_sales.sql +++ b/models/silver/nft/sales/silver__complete_nft_sales.sql @@ -260,6 +260,48 @@ WHERE {{ this }} ) {% endif %} +UNION ALL +SELECT + block_number, + block_timestamp, + tx_hash, + event_index, + event_type, + platform_address, + platform_name, + platform_exchange_version, + seller_address, + buyer_address, + nft_address, + erc1155_value :: STRING AS erc1155_value, + tokenId, + currency_address, + total_price_raw, + total_fees_raw, + platform_fee_raw, + creator_fee_raw, + tx_fee, + origin_from_address, + origin_to_address, + origin_function_signature, + input_data, + nft_log_id, + _log_id, + _inserted_timestamp +FROM + {{ ref('silver__element_sales') }} + +{% if is_incremental() and 'element' not in var('HEAL_MODELS') %} +WHERE + _inserted_timestamp >= ( + SELECT + MAX( + _inserted_timestamp + ) - INTERVAL '{{ var("LOOKBACK", "4 hours") }}' + FROM + {{ this }} + ) +{% endif %} ), prices_raw AS ( SELECT diff --git a/models/silver/nft/sales/silver__element_sales.sql b/models/silver/nft/sales/silver__element_sales.sql new file mode 100644 index 00000000..2b5a4bd0 --- /dev/null +++ b/models/silver/nft/sales/silver__element_sales.sql @@ -0,0 +1,283 @@ +{{ config( + materialized = 'incremental', + incremental_strategy = 'delete+insert', + unique_key = "block_number", + cluster_by = ['block_timestamp::DATE'], + tags = ['curated','reorg'] +) }} + +WITH settings AS ( + + SELECT + '2023-11-20' AS start_date, + '0x2317d8b224328644759319dffa2a5da77c72e0e9' AS main_address, + '0x99302eaef620fba2131bfeff336188961d62747a' AS fee_address, + '0x4200000000000000000000000000000000000006' AS wrapped_native_address +), +raw AS ( + SELECT + tx_hash, + event_index, + event_name, + decoded_flat, + IFF( + event_name LIKE '%Buy%', + 'bid_won', + 'sale' + ) AS event_type, + decoded_flat :erc20Token :: STRING AS currency_address_raw, + COALESCE( + decoded_flat :erc20TokenAmount, + decoded_flat :erc20FillAmount + ) :: INT AS amount_raw, + COALESCE( + decoded_flat :erc721Token, + decoded_flat :erc1155Token + ) :: STRING AS nft_address, + COALESCE( + decoded_flat :erc721TokenId, + decoded_flat :erc1155TokenId + ) :: STRING AS tokenid, + decoded_flat :erc1155FillAmount :: STRING AS erc1155_value, + IFF( + erc1155_value IS NULL, + 'erc721', + 'erc1155' + ) AS nft_type, + decoded_flat :maker :: STRING AS maker, + decoded_flat :taker :: STRING AS taker, + IFF( + event_name LIKE '%Buy%', + taker, + maker + ) AS seller_address, + IFF( + event_name LIKE '%Buy%', + maker, + taker + ) AS buyer_address, + decoded_flat :fees AS fees_array, + decoded_flat :orderHash :: STRING AS orderhash, + ROW_NUMBER() over ( + PARTITION BY tx_hash + ORDER BY + event_index ASC + ) AS intra_grouping_seller_fill, + block_timestamp, + block_number, + _log_id, + _inserted_timestamp + FROM + {{ ref('silver__decoded_logs') }} + WHERE + block_timestamp :: DATE >= ( + SELECT + start_date + FROM + settings + ) + AND contract_address = ( + SELECT + main_address + FROM + settings + ) + AND event_name IN ( + 'ERC721BuyOrderFilled', + 'ERC721SellOrderFilled', + 'ERC1155SellOrderFilled', + 'ERC1155BuyOrderFilled' + ) + +{% if is_incremental() %} +AND _inserted_timestamp >= ( + SELECT + MAX(_inserted_timestamp) - INTERVAL '12 hours' + FROM + {{ this }} +) +{% endif %} +), +raw_fees AS ( + SELECT + tx_hash, + event_index, + INDEX, + VALUE :amount :: INT AS fee_amount_raw, + VALUE :recipient :: STRING AS fee_recipient, + CASE + WHEN fee_recipient = ( + SELECT + fee_address + FROM + settings + ) THEN fee_amount_raw + ELSE 0 + END AS platform_amount_raw, + CASE + WHEN fee_recipient != ( + SELECT + fee_address + FROM + settings + ) THEN fee_amount_raw + ELSE 0 + END AS creator_amount_raw + FROM + raw, + LATERAL FLATTEN ( + input => fees_array + ) +), +raw_fees_agg AS ( + SELECT + tx_hash, + event_index, + SUM(platform_amount_raw) AS platform_fee_raw_, + SUM(creator_amount_raw) AS creator_fee_raw_ + FROM + raw_fees + GROUP BY + ALL +), +new_base AS ( + SELECT + tx_hash, + intra_grouping_seller_fill, + event_index, + event_name, + decoded_flat, + event_type, + currency_address_raw, + amount_raw, + nft_address, + tokenid, + erc1155_value, + nft_type, + maker, + taker, + seller_address, + buyer_address, + amount_raw AS total_price_raw, + COALESCE( + platform_fee_raw_, + 0 + ) + COALESCE( + creator_fee_raw_, + 0 + ) AS total_fees_raw, + COALESCE( + platform_fee_raw_, + 0 + ) AS platform_fee_raw, + COALESCE( + creator_fee_raw_, + 0 + ) AS creator_fee_raw, + fees_array, + orderhash, + block_timestamp, + block_number, + _log_id, + _inserted_timestamp + FROM + raw + LEFT JOIN raw_fees_agg USING ( + tx_hash, + event_index + ) +), +tx_data AS ( + SELECT + tx_hash, + from_address AS origin_from_address, + to_address AS origin_to_address, + origin_function_signature, + tx_fee, + input_data + FROM + {{ ref('silver__transactions') }} + WHERE + block_timestamp :: DATE >= ( + SELECT + start_date + FROM + settings + ) + AND tx_hash IN ( + SELECT + DISTINCT tx_hash + FROM + new_base + ) + +{% if is_incremental() %} +AND _inserted_timestamp >= ( + SELECT + MAX(_inserted_timestamp) - INTERVAL '12 hours' + FROM + {{ this }} +) +{% endif %} +) +SELECT + block_number, + block_timestamp, + tx_hash, + event_index, + event_name, + decoded_flat, + event_type, + ( + SELECT + main_address + FROM + settings + ) AS platform_address, + 'element' AS platform_name, + 'element v1' AS platform_exchange_version, + intra_grouping_seller_fill, + currency_address_raw, + amount_raw, + nft_address, + tokenid, + erc1155_value, + nft_type, + maker, + taker, + seller_address, + buyer_address, + IFF( + currency_address_raw = '0xeeeeeeeeeeeeeeeeeeeeeeeeeeeeeeeeeeeeeeee', + 'ETH', + currency_address_raw + ) AS currency_address, + total_price_raw, + total_fees_raw, + platform_fee_raw, + creator_fee_raw, + fees_array, + orderhash, + origin_from_address, + origin_to_address, + origin_function_signature, + tx_fee, + input_data, + _log_id, + CONCAT( + nft_address, + '-', + tokenId, + '-', + platform_exchange_version, + '-', + _log_id + ) AS nft_log_id, + _inserted_timestamp +FROM + new_base + INNER JOIN tx_data USING (tx_hash) qualify ROW_NUMBER() over ( + PARTITION BY nft_log_id + ORDER BY + _inserted_timestamp DESC + ) = 1 diff --git a/models/silver/nft/sales/silver__element_sales.yml b/models/silver/nft/sales/silver__element_sales.yml new file mode 100644 index 00000000..7f3b7f75 --- /dev/null +++ b/models/silver/nft/sales/silver__element_sales.yml @@ -0,0 +1,115 @@ +version: 2 +models: + - name: silver__element_sales + tests: + - dbt_utils.unique_combination_of_columns: + combination_of_columns: + - nft_log_id + columns: + - name: BLOCK_NUMBER + tests: + - not_null + - dbt_expectations.expect_column_values_to_be_in_type_list: + column_type_list: + - NUMBER + - FLOAT + - name: BLOCK_TIMESTAMP + tests: + - not_null + - dbt_expectations.expect_row_values_to_have_recent_data: + datepart: day + interval: 1 + - dbt_expectations.expect_column_values_to_be_in_type_list: + column_type_list: + - TIMESTAMP_LTZ + - TIMESTAMP_NTZ + - name: TX_HASH + tests: + - not_null + - dbt_expectations.expect_column_values_to_match_regex: + regex: 0[xX][0-9a-fA-F]+ + - name: SELLER_ADDRESS + tests: + - not_null + - dbt_expectations.expect_column_values_to_match_regex: + regex: 0[xX][0-9a-fA-F]+ + - name: BUYER_ADDRESS + tests: + - not_null + - dbt_expectations.expect_column_values_to_match_regex: + regex: 0[xX][0-9a-fA-F]+ + - name: NFT_ADDRESS + tests: + - not_null + - dbt_expectations.expect_column_values_to_match_regex: + regex: 0[xX][0-9a-fA-F]+ + - name: TOKENID + tests: + - not_null + - name: CURRENCY_ADDRESS + tests: + - not_null + - name: TOTAL_PRICE_RAW + tests: + - not_null + - dbt_expectations.expect_column_values_to_be_in_type_list: + column_type_list: + - NUMBER + - FLOAT + - name: TOTAL_FEES_RAW + tests: + - not_null + - dbt_expectations.expect_column_values_to_be_in_type_list: + column_type_list: + - NUMBER + - FLOAT + - name: PLATFORM_FEE_RAW + tests: + - not_null + - dbt_expectations.expect_column_values_to_be_in_type_list: + column_type_list: + - NUMBER + - FLOAT + - name: CREATOR_FEE_RAW + tests: + - not_null + - dbt_expectations.expect_column_values_to_be_in_type_list: + column_type_list: + - NUMBER + - FLOAT + - name: TX_FEE + tests: + - not_null + - dbt_expectations.expect_column_values_to_be_in_type_list: + column_type_list: + - NUMBER + - FLOAT + - name: NFT_LOG_ID + tests: + - not_null + - name: _LOG_ID + tests: + - not_null + - name: ORIGIN_FROM_ADDRESS + tests: + - not_null + - dbt_expectations.expect_column_values_to_match_regex: + regex: 0[xX][0-9a-fA-F]+ + - name: ORIGIN_TO_ADDRESS + tests: + - not_null + - dbt_expectations.expect_column_values_to_match_regex: + regex: 0[xX][0-9a-fA-F]+ + - name: ORIGIN_FUNCTION_SIGNATURE + tests: + - not_null + - dbt_expectations.expect_column_values_to_match_regex: + regex: 0[xX][0-9a-fA-F]+ + - name: EVENT_TYPE + tests: + - not_null + - dbt_expectations.expect_column_values_to_be_in_set: + value_set: ['bid_won', 'sale'] + - name: INPUT_DATA + tests: + - not_null \ No newline at end of file diff --git a/models/silver/nft/sales/silver__quix_seaport_sales.sql b/models/silver/nft/sales/silver__quix_seaport_sales.sql index 42086ec4..ad382631 100644 --- a/models/silver/nft/sales/silver__quix_seaport_sales.sql +++ b/models/silver/nft/sales/silver__quix_seaport_sales.sql @@ -3,8 +3,7 @@ incremental_strategy = 'delete+insert', unique_key = 'block_number', cluster_by = ['block_timestamp::DATE', '_inserted_timestamp::DATE'], - tags = ['curated','reorg'] - + tags = ['stale'] ) }} WITH seaport_fees_wallet AS ( diff --git a/models/silver/nft/sales/silver__seaport_1_4_sales.sql b/models/silver/nft/sales/silver__seaport_1_4_sales.sql index f0bd008d..1567228a 100644 --- a/models/silver/nft/sales/silver__seaport_1_4_sales.sql +++ b/models/silver/nft/sales/silver__seaport_1_4_sales.sql @@ -3,7 +3,7 @@ incremental_strategy = 'delete+insert', unique_key = 'block_number', cluster_by = ['block_timestamp::DATE'], - tags = ['curated','reorg'] + tags = ['stale'] ) }} diff --git a/models/silver/nft/sales/silver__seaport_1_5_sales.sql b/models/silver/nft/sales/silver__seaport_1_5_sales.sql index c4f11ea5..f5661e22 100644 --- a/models/silver/nft/sales/silver__seaport_1_5_sales.sql +++ b/models/silver/nft/sales/silver__seaport_1_5_sales.sql @@ -37,7 +37,7 @@ raw_decoded_logs AS ( {% if is_incremental() %} AND _inserted_timestamp >= ( SELECT - MAX(_inserted_timestamp) - INTERVAL '24 hours' + MAX(_inserted_timestamp) - INTERVAL '12 hours' FROM {{ this }} ) @@ -79,7 +79,7 @@ raw_logs AS ( {% if is_incremental() %} AND _inserted_timestamp >= ( SELECT - MAX(_inserted_timestamp) - INTERVAL '24 hours' + MAX(_inserted_timestamp) - INTERVAL '12 hours' FROM {{ this }} ) @@ -1865,7 +1865,7 @@ tx_data AS ( {% if is_incremental() %} AND _inserted_timestamp >= ( SELECT - MAX(_inserted_timestamp) - INTERVAL '24 hours' + MAX(_inserted_timestamp) - INTERVAL '12 hours' FROM {{ this }} ) @@ -1906,7 +1906,7 @@ nft_transfer_operator AS ( {% if is_incremental() %} AND _inserted_timestamp >= ( SELECT - MAX(_inserted_timestamp) - INTERVAL '24 hours' + MAX(_inserted_timestamp) - INTERVAL '12 hours' FROM {{ this }} ) diff --git a/models/silver/nft/sales/silver__seaport_1_6_sales.sql b/models/silver/nft/sales/silver__seaport_1_6_sales.sql index 19277540..31eaacaa 100644 --- a/models/silver/nft/sales/silver__seaport_1_6_sales.sql +++ b/models/silver/nft/sales/silver__seaport_1_6_sales.sql @@ -36,7 +36,7 @@ raw_decoded_logs AS ( {% if is_incremental() %} AND _inserted_timestamp >= ( SELECT - MAX(_inserted_timestamp) - INTERVAL '24 hours' + MAX(_inserted_timestamp) - INTERVAL '12 hours' FROM {{ this }} ) @@ -77,7 +77,7 @@ raw_logs AS ( {% if is_incremental() %} AND _inserted_timestamp >= ( SELECT - MAX(_inserted_timestamp) - INTERVAL '24 hours' + MAX(_inserted_timestamp) - INTERVAL '12 hours' FROM {{ this }} ) @@ -1863,7 +1863,7 @@ tx_data AS ( {% if is_incremental() %} AND _inserted_timestamp >= ( SELECT - MAX(_inserted_timestamp) - INTERVAL '24 hours' + MAX(_inserted_timestamp) - INTERVAL '12 hours' FROM {{ this }} ) @@ -1904,7 +1904,7 @@ nft_transfer_operator AS ( {% if is_incremental() %} AND _inserted_timestamp >= ( SELECT - MAX(_inserted_timestamp) - INTERVAL '24 hours' + MAX(_inserted_timestamp) - INTERVAL '12 hours' FROM {{ this }} )