diff --git a/models/core/core__ez_nft_sales.sql b/models/core/core__ez_nft_sales.sql index 1b40af7..fbb896c 100644 --- a/models/core/core__ez_nft_sales.sql +++ b/models/core/core__ez_nft_sales.sql @@ -29,27 +29,6 @@ gold_nfts AS ( counterparties FROM silver_nfts - WHERE - tx_id NOT IN ( - -- the following txs have no NFT movement via withdraw/deposit - '8620792f30d607a35eb5a7ffe6ea2a088d448f1b706e8585ca8ae8697655e6fa', - '489584d6def5e583d79864046e47b37888c935bfad6b2b17ac67be4b04209f55', - '0934ec1c9bf6c52cbd11e3e4e39154d147af06c95a8bdbc3936839ed19665090', - '69d577729d6abf7b3e71e91b0f8df737f044f5cec40b2872376b80ddb934a7e2', - '43d7cefcdb35aee175b8c573a247bcfa029a82db7f99265d0b14fbb6c9b63360', - '507fc7eda60d5f4706891d3f48be70f20c6c115ee81e419dc9daa673e87c77c7', - 'f9c0de48de30624b2f42924f69b8e9ef36fb1995ad37921534131b2f28888027', - '4b98e11f4482231c7d41c921874c2c0dfacdb0b537020e7e4030d683aebbd98a', - '6dc3a5bb564d1935ccea5213da686d4f367ffb4a21361e0badc841cb84e2d5dc', - '614d1018d5e93711f50dbbeb9b779ba3b7e8577e08c34d69c905cef45239c03e', - 'fbc6ef3a9f3e93fcd86f2e528a0eb81fee227ff0a4807668d12d58546ac40848', - 'c6b93aaa36cf77e6af54ca4690b15e7da85c52adaf71f8227c9bfaf65c13530f', - 'f5af123b63b166a172da4c31e06c1b70103ebc746d92674cb94df4b0cb84859e', - 'cca5fb19473b07adaa96a91f73e69de69270a641d910dde10a6933a3af8ac5f3', - -- the following are soulmade packs being broken into components - '78b723f39760b1601eaa76493d9f687035384271fbcfc47dc4b03cd906ef4b0a', - '67150dc5acd70a950b4d46ae45b3507dddc5da15e751e0597cef03159b05d433' - ) ) SELECT * diff --git a/models/silver/silver__nft_sales.sql b/models/silver/silver__nft_sales.sql index 2d38630..aa93a96 100644 --- a/models/silver/silver__nft_sales.sql +++ b/models/silver/silver__nft_sales.sql @@ -23,28 +23,12 @@ WHERE ) {% endif %} ), -secondary AS ( +secondary_mkts AS ( SELECT * FROM {{ ref('silver__nft_transactions_secondary_market') }} -{% if is_incremental() %} -WHERE - _inserted_timestamp >= ( - SELECT - MAX(_inserted_timestamp) - FROM - {{ this }} - ) -{% endif %} -), -fabricant AS ( - SELECT - * - FROM - {{ ref('silver__nft_transactions_fabricant') }} - {% if is_incremental() %} WHERE _inserted_timestamp >= ( @@ -92,26 +76,7 @@ combo AS ( tokenflow, counterparties FROM - secondary - UNION - SELECT - tx_id, - block_height, - block_timestamp, - marketplace, - nft_collection, - nft_id, - buyer, - seller, - price, - currency, - tx_succeeded, - _ingested_at, - _inserted_timestamp, - tokenflow, - counterparties - FROM - fabricant + secondary_mkts ) SELECT * diff --git a/models/silver/silver__nft_transactions_fabricant.sql b/models/silver/silver__nft_transactions_fabricant.sql deleted file mode 100644 index e06e11a..0000000 --- a/models/silver/silver__nft_transactions_fabricant.sql +++ /dev/null @@ -1,211 +0,0 @@ -{{ config( - materialized = 'incremental', - incremental_strategy = 'delete+insert', - cluster_by = ['_inserted_timestamp::DATE'], - unique_key = 'tx_id', - tags = ['nft'] -) }} - -WITH silver_events AS ( - - SELECT - * - FROM - {{ ref('silver__events_final') }} - -{% if is_incremental() %} -WHERE - _inserted_timestamp >= ( - SELECT - MAX(_inserted_timestamp) - FROM - {{ this }} - ) -{% endif %} -), -fabricant_mkt_txs AS ( - SELECT - * - FROM - silver_events - WHERE - event_contract = 'A.09e03b1f871b3513.TheFabricantMarketplace' -), -fabricant_events AS ( - SELECT - * - FROM - silver_events - WHERE - tx_id IN ( - SELECT - tx_id - FROM - fabricant_mkt_txs - ) -), -nft_purchase AS ( - SELECT - tx_id, - event_index, - block_timestamp, - block_height, - tx_succeeded, - event_contract AS event_contract_purchase, - event_data :buyer :: STRING AS buyer_purchase, - event_data :listingID :: STRING AS listing_id, - event_data :seller :: STRING AS seller_purchase, - _ingested_at, - _inserted_timestamp - FROM - fabricant_events - WHERE - event_type = 'NFTPurchased' -), -cost AS ( - SELECT - tx_id, - event_index, - block_timestamp, - event_contract AS event_contract_currency, - event_data :amount :: FLOAT AS amount, - event_data :from :: STRING AS buyer_cost - FROM - fabricant_events - WHERE - event_index = 0 - AND event_type = 'TokensWithdrawn' -), -seller_data AS ( - SELECT - tx_id, - event_index, - block_timestamp, - event_contract AS event_contract_withdraw, - event_data :from :: STRING AS seller, - event_data :id :: STRING AS nft_id - FROM - fabricant_events - WHERE - event_type = 'Withdraw' -), -buyer_data AS ( - SELECT - tx_id, - event_index, - block_timestamp, - event_contract AS event_contract_deposit, - event_data :to :: STRING AS buyer, - event_data :id :: STRING AS nft_id - FROM - fabricant_events - WHERE - event_type = 'Deposit' -), -fabricant_nft_sales AS ( - SELECT - p.block_timestamp, - p.block_height, - p.tx_id, - p.tx_succeeded, - p.event_index AS purchase_event_index, - event_contract_purchase, - buyer_purchase, - listing_id, - seller_purchase, - C.event_index AS event_index_cost, - event_contract_currency, - amount, - buyer_cost, - s.event_index AS event_index_withdraw, - event_contract_withdraw, - seller, - s.nft_id AS nft_id_withdraw, - b.event_index AS event_index_deposit, - event_contract_deposit, - buyer, - b.nft_id AS nft_id_deposit, - _ingested_at, - _inserted_timestamp - FROM - nft_purchase p - LEFT JOIN cost C USING (tx_id) - LEFT JOIN seller_data s USING (tx_id) - LEFT JOIN buyer_data b USING (tx_id) -), -step_data AS ( - SELECT - tx_id, - event_index, - event_type, - event_data - FROM - silver_events - WHERE - tx_id IN ( - SELECT - tx_id - FROM - fabricant_nft_sales - ) - AND event_type IN ( - 'TokensWithdrawn', - 'TokensDeposited', - 'ForwardedDeposit', - 'RoyaltyDeposited' - ) -), -counterparty_data AS ( - SELECT - tx_id, - ARRAY_AGG(OBJECT_CONSTRUCT(event_type, event_data)) within GROUP ( - ORDER BY - event_index - ) AS tokenflow, - ARRAY_SIZE(tokenflow) AS steps, - ARRAY_AGG(event_type) within GROUP ( - ORDER BY - event_index - ) AS action, - ARRAY_AGG(event_data) within GROUP ( - ORDER BY - event_index - ) AS step_data, - ARRAY_AGG(COALESCE(event_data :to, event_data :from) :: STRING) within GROUP ( - ORDER BY - event_index - ) AS counterparties - FROM - step_data - GROUP BY - 1 -), -FINAL AS ( - SELECT - block_timestamp, - block_height, - fns.tx_id, - event_contract_purchase AS marketplace, - listing_id, - event_contract_currency AS currency, - amount AS price, - event_contract_withdraw AS nft_collection, - seller, - nft_id_withdraw AS nft_id, - buyer, - cd.tokenflow, - cd.steps AS num_steps, - cd.action AS step_action, - cd.step_data, - cd.counterparties, - tx_succeeded, - _ingested_at, - _inserted_timestamp - FROM - fabricant_nft_sales fns - LEFT JOIN counterparty_data cd USING (tx_id) -) -SELECT - * -FROM - FINAL diff --git a/models/silver/silver__nft_transactions_fabricant.yml b/models/silver/silver__nft_transactions_fabricant.yml deleted file mode 100644 index e645735..0000000 --- a/models/silver/silver__nft_transactions_fabricant.yml +++ /dev/null @@ -1,178 +0,0 @@ -version: 2 - -models: - - name: silver__nft_transactions_fabricant - description: |- - This table filters all NFT sales that interact with the marketplace contract for fabricant. - tests: - - dbt_utils.unique_combination_of_columns: - combination_of_columns: - - tx_id - - columns: - - name: tx_id - description: "{{ doc('tx_id') }}" - tests: - - not_null - - unique - - dbt_expectations.expect_column_values_to_be_in_type_list: - column_type_list: - - STRING - - VARCHAR - - - name: block_height - description: "{{ doc('block_height') }}" - tests: - - not_null - - dbt_expectations.expect_column_values_to_be_in_type_list: - column_type_list: - - NUMBER - - FLOAT - - - name: block_timestamp - description: "{{ doc('block_timestamp') }}" - tests: - - not_null - - dbt_expectations.expect_column_values_to_be_in_type_list: - column_type_list: - - TIMESTAMP_NTZ - - - name: marketplace - description: "{{ doc('marketplace') }}" - tests: - - not_null - - dbt_expectations.expect_column_values_to_be_in_type_list: - column_type_list: - - STRING - - VARCHAR - - - name: listing_id - description: "{{ doc('listing_id') }}" - tests: - - not_null - - dbt_expectations.expect_column_values_to_be_in_type_list: - column_type_list: - - STRING - - VARCHAR - - - name: nft_collection - description: "{{ doc('nft_collection') }}" - tests: - - not_null - - dbt_expectations.expect_column_values_to_be_in_type_list: - column_type_list: - - STRING - - VARCHAR - - - name: nft_id - description: "{{ doc('nft_id') }}" - tests: - - not_null - - dbt_expectations.expect_column_values_to_be_in_type_list: - column_type_list: - - STRING - - VARCHAR - - NUMBER - - - name: currency - description: "{{ doc('currency') }}" - tests: - - not_null - - dbt_expectations.expect_column_values_to_be_in_type_list: - column_type_list: - - STRING - - VARCHAR - - - name: price - description: "{{ doc('price') }}" - tests: - - not_null - - dbt_expectations.expect_column_values_to_be_in_type_list: - column_type_list: - - NUMBER - - FLOAT - - - name: seller - description: "{{ doc('seller') }}" - tests: - - not_null - - dbt_expectations.expect_column_values_to_be_in_type_list: - column_type_list: - - STRING - - VARCHAR - - - name: buyer - description: "{{ doc('buyer') }}" - tests: - - not_null - - dbt_expectations.expect_column_values_to_be_in_type_list: - column_type_list: - - STRING - - VARCHAR - - - name: tokenflow - description: "{{ doc('tokenflow') }}" - tests: - - not_null - - dbt_expectations.expect_column_values_to_be_in_type_list: - column_type_list: - - ARRAY - - OBJECT - - VARIANT - - - name: num_steps - description: "{{ doc('num_steps') }}" - tests: - - not_null - - dbt_expectations.expect_column_values_to_be_in_type_list: - column_type_list: - - NUMBER - - - name: step_action - description: "{{ doc('step_action') }}" - tests: - - not_null - - dbt_expectations.expect_column_values_to_be_in_type_list: - column_type_list: - - ARRAY - - OBJECT - - VARIANT - - - name: step_data - description: "{{ doc('step_data') }}" - tests: - - not_null - - dbt_expectations.expect_column_values_to_be_in_type_list: - column_type_list: - - ARRAY - - OBJECT - - VARIANT - - - name: counterparties - description: "{{ doc('counterparties') }}" - tests: - - not_null - - dbt_expectations.expect_column_values_to_be_in_type_list: - column_type_list: - - ARRAY - - OBJECT - - VARIANT - - - name: tx_succeeded - description: "{{ doc('tx_succeeded') }}" - tests: - - not_null - - dbt_expectations.expect_column_values_to_be_in_type_list: - column_type_list: - - BOOLEAN - - - name: _ingested_at - description: "{{ doc('_ingested_at') }}" - - - name: _inserted_timestamp - description: "{{ doc('_inserted_timestamp') }}" - tests: - - not_null - - dbt_expectations.expect_column_values_to_be_in_type_list: - column_type_list: - - TIMESTAMP_NTZ diff --git a/models/silver/silver__nft_transactions_secondary_market.sql b/models/silver/silver__nft_transactions_secondary_market.sql index d45d89b..2cdc445 100644 --- a/models/silver/silver__nft_transactions_secondary_market.sql +++ b/models/silver/silver__nft_transactions_secondary_market.sql @@ -12,55 +12,97 @@ WITH silver_events AS ( * FROM {{ ref('silver__events_final') }} + WHERE + event_data :: STRING != '{}' {% if is_incremental() %} -WHERE - _inserted_timestamp >= ( - SELECT - MAX(_inserted_timestamp) - FROM - {{ this }} - ) +AND _inserted_timestamp >= ( + SELECT + MAX(_inserted_timestamp) + FROM + {{ this }} +) {% endif %} ), -listing_data AS ( +sale_trigger AS ( SELECT tx_id, block_timestamp, block_height, tx_succeeded, - event_index AS event_index_listing, - event_contract AS event_contract_listing, - event_data AS event_data_listing, - event_data :nftID :: STRING AS nft_id_listing, - event_data :nftType :: STRING AS nft_collection_listing, - event_data :purchased :: BOOLEAN AS purchased_listing, + event_contract AS marketplace, + event_data, + COALESCE( + event_data :purchased :: BOOLEAN, + TRUE + ) AS is_purchased, _ingested_at, _inserted_timestamp FROM silver_events WHERE - event_type = 'ListingCompleted' - AND event_contract = 'A.4eb8a10cb9f87357.NFTStorefront' -- general storefront - AND purchased_listing = TRUE + is_purchased + AND -- each market uses a slightly different sale trigger + ( + ( + event_contract = 'A.64f83c60989ce555.ChainmonstersMarketplace' + AND event_type = 'CollectionRemovedSaleOffer' + ) + OR ( + event_contract = 'A.921ea449dffec68a.FlovatarMarketplace' + AND event_type IN ( + 'FlovatarPurchased', + 'FlovatarComponentPurchased' + ) + ) + OR ( + event_contract = 'A.09e03b1f871b3513.TheFabricantMarketplace' + AND event_type = 'NFTPurchased' + ) + OR ( + event_contract = 'A.2162bbe13ade251e.MatrixMarketOpenOffer' + AND event_type = 'OfferCompleted' + ) + OR ( + event_contract = 'A.4eb8a10cb9f87357.NFTStorefront' -- general storefront + AND event_type = 'ListingCompleted' + ) + OR ( + event_contract = 'A.85b075e08d13f697.OlympicPinMarket' + AND event_type = 'PiecePurchased' + ) + OR ( + event_contract = 'A.5b82f21c0edf76e3.StarlyCardMarket' + AND event_type = 'CollectionRemovedSaleOffer' + ) + ) ), excl_multi_buys AS ( SELECT tx_id, COUNT(1) AS record_count FROM - listing_data + sale_trigger GROUP BY 1 HAVING record_count = 1 ), -purchase_data AS ( +omit_nft_nontransfers AS ( SELECT tx_id, - event_contract AS currency, - event_data :amount :: DOUBLE AS amount, - event_data :from :: STRING AS buyer_purchase + ARRAY_AGG( + DISTINCT event_type + ) AS events, + ARRAY_SIZE( + array_intersection( + ['Deposit', 'Withdraw', 'FlovatarSaleWithdrawn', 'FlovatarComponentSaleWithdrawn'], + events + ) + ) = 2 AS nft_transferred, + count_if( + event_type = 'Deposit' + ) AS nft_deposits FROM silver_events WHERE @@ -70,15 +112,15 @@ purchase_data AS ( FROM excl_multi_buys ) - AND event_index = 0 - AND event_type = 'TokensWithdrawn' + GROUP BY + 1 + HAVING + nft_deposits = 1 ), -purchase_data_2 AS ( +first_token_withdraw AS ( SELECT tx_id, - event_contract AS currency, - event_data :amount :: DOUBLE AS amount, - event_data :from :: STRING AS buyer_purchase + MIN(event_index) AS min_index FROM silver_events WHERE @@ -86,35 +128,50 @@ purchase_data_2 AS ( SELECT tx_id FROM - excl_multi_buys + omit_nft_nontransfers + WHERE + nft_transferred ) - AND tx_id NOT IN ( + AND event_type = 'TokensWithdrawn' + GROUP BY + 1 +), +-- 3 most important events are the first TokenWithdraw, then Withdraw and Deposit (NFT movement) +token_withdraw_event AS ( + SELECT + tx_id, + event_contract AS currency, + event_data :amount :: DOUBLE AS amount, + event_data :from :: STRING AS buyer_purchase, + min_index + FROM + silver_events + LEFT JOIN first_token_withdraw USING (tx_id) + WHERE + tx_id IN ( SELECT tx_id FROM - purchase_data + omit_nft_nontransfers + WHERE + nft_transferred ) - AND event_index = 1 + AND event_index = min_index AND event_type = 'TokensWithdrawn' ), -purchase_data_final AS ( - SELECT - * - FROM - purchase_data - UNION - SELECT - * - FROM - purchase_data_2 -), -seller_data AS ( +nft_withdraw_event_seller AS ( SELECT tx_id, event_index AS event_index_seller, event_contract AS nft_collection_seller, - event_data :from :: STRING AS seller, - event_data :id :: STRING AS nft_id_seller + COALESCE( + event_data :from, + event_data :address + ) :: STRING AS seller, + COALESCE( + event_data :id, + event_data :tokenId + ) :: STRING AS nft_id_seller FROM silver_events WHERE @@ -122,11 +179,17 @@ seller_data AS ( SELECT tx_id FROM - excl_multi_buys + omit_nft_nontransfers + WHERE + nft_transferred + ) + AND event_type IN ( + 'Withdraw', + 'FlovatarSaleWithdrawn', + 'FlovatarComponentSaleWithdrawn' -- if adding anything new, don't forget about omit_nft_nontransfers check! ) - AND event_type = 'Withdraw' ), -deposit_data AS ( +nft_deposit_event_buyer AS ( SELECT tx_id, event_contract AS nft_collection_deposit, @@ -139,24 +202,44 @@ deposit_data AS ( SELECT tx_id FROM - excl_multi_buys + omit_nft_nontransfers + WHERE + nft_transferred ) AND event_type = 'Deposit' ), nft_sales AS ( SELECT - * + e.tx_id, + e.block_timestamp, + e.block_height, + e.tx_succeeded, + e.is_purchased, + e.marketplace, + w.currency, + w.amount, + w.buyer_purchase, + s.nft_collection_seller, + s.seller, + s.nft_id_seller, + b.nft_collection_deposit, + b.nft_id_deposit, + b.buyer_deposit, + e._ingested_at, + e._inserted_timestamp FROM - listing_data - LEFT JOIN purchase_data_final USING (tx_id) - LEFT JOIN seller_data USING (tx_id) - LEFT JOIN deposit_data USING (tx_id) + sale_trigger e + LEFT JOIN token_withdraw_event w USING (tx_id) + LEFT JOIN nft_withdraw_event_seller s USING (tx_id) + LEFT JOIN nft_deposit_event_buyer b USING (tx_id) WHERE tx_id IN ( SELECT tx_id FROM - excl_multi_buys + omit_nft_nontransfers + WHERE + nft_transferred ) ), step_data AS ( @@ -177,7 +260,8 @@ step_data AS ( AND event_type IN ( 'TokensWithdrawn', 'TokensDeposited', - 'ForwardedDeposit' + 'ForwardedDeposit', + 'RoyaltyDeposited' ) ), counterparty_data AS ( @@ -210,12 +294,9 @@ FINAL AS ( ns.tx_id, block_timestamp, block_height, - event_contract_listing AS marketplace, - event_data_listing, - nft_collection_seller AS nft_collection, - event_data_listing :storefrontResourceID :: NUMBER AS storefront_id, - event_data_listing :listingResourceID :: NUMBER AS listing_id, - nft_id_listing AS nft_id, + marketplace, + nft_collection_deposit AS nft_collection, + nft_id_seller AS nft_id, currency, amount AS price, seller, diff --git a/models/silver/silver__nft_transactions_secondary_market.yml b/models/silver/silver__nft_transactions_secondary_market.yml index 58a456f..6708518 100644 --- a/models/silver/silver__nft_transactions_secondary_market.yml +++ b/models/silver/silver__nft_transactions_secondary_market.yml @@ -51,33 +51,6 @@ models: - STRING - VARCHAR - - name: event_data_listing - description: "{{ doc('event_data_listing') }}" - tests: - - not_null - - dbt_expectations.expect_column_values_to_be_in_type_list: - column_type_list: - - ARRAY - - VARIANT - - OBJECT - - - name: storefront_id - description: "{{ doc('storefront_id') }}" - tests: - - not_null - - dbt_expectations.expect_column_values_to_be_in_type_list: - column_type_list: - - NUMBER - - - name: listing_id - description: "{{ doc('listing_id') }}" - tests: - - not_null - - unique - - dbt_expectations.expect_column_values_to_be_in_type_list: - column_type_list: - - NUMBER - - name: nft_collection description: "{{ doc('nft_collection') }}" tests: