mirror of
https://github.com/FlipsideCrypto/ethereum-models.git
synced 2026-02-06 14:06:53 +00:00
parent
4a354cebac
commit
7ad674285e
@ -1,249 +0,0 @@
|
||||
{{ config(
|
||||
materialized = 'incremental',
|
||||
incremental_strategy = 'delete+insert',
|
||||
unique_key = "block_number",
|
||||
cluster_by = ['block_timestamp::DATE'],
|
||||
post_hook = "ALTER TABLE {{ this }} ADD SEARCH OPTIMIZATION ON EQUALITY(tx_hash, event_type, nft_address, project_name, nft_from_address, nft_to_address, mint_token_symbol, mint_token_address), SUBSTRING(event_type, nft_address, project_name, nft_from_address, nft_to_address, mint_token_symbol, mint_token_address)",
|
||||
tags = ['silver','nft','curated']
|
||||
) }}
|
||||
|
||||
WITH nft_mints AS (
|
||||
|
||||
SELECT
|
||||
block_number,
|
||||
tx_hash,
|
||||
block_timestamp,
|
||||
contract_address,
|
||||
project_name,
|
||||
from_address,
|
||||
to_address,
|
||||
tokenId,
|
||||
erc1155_value,
|
||||
'nft_mint' AS event_type,
|
||||
_log_id,
|
||||
modified_timestamp AS _inserted_timestamp
|
||||
FROM
|
||||
{{ ref('silver__nft_transfers') }}
|
||||
WHERE
|
||||
event_type = 'mint'
|
||||
|
||||
{% if is_incremental() %}
|
||||
AND _inserted_timestamp >= (
|
||||
SELECT
|
||||
MAX(_inserted_timestamp) - INTERVAL '{{ var("LOOKBACK", "4 hours") }}'
|
||||
FROM
|
||||
{{ this }}
|
||||
)
|
||||
{% endif %}
|
||||
),
|
||||
mint_price AS (
|
||||
SELECT
|
||||
tx_hash,
|
||||
VALUE AS eth_value,
|
||||
tx_fee
|
||||
FROM
|
||||
{{ ref('core__fact_transactions') }}
|
||||
WHERE
|
||||
tx_succeeded
|
||||
AND tx_hash IN (
|
||||
SELECT
|
||||
tx_hash
|
||||
FROM
|
||||
nft_mints
|
||||
)
|
||||
|
||||
{% if is_incremental() %}
|
||||
AND modified_timestamp >= (
|
||||
SELECT
|
||||
MAX(_inserted_timestamp) - INTERVAL '{{ var("LOOKBACK", "4 hours") }}'
|
||||
FROM
|
||||
{{ this }}
|
||||
)
|
||||
{% endif %}
|
||||
),
|
||||
tokens_per_tx AS (
|
||||
SELECT
|
||||
tx_hash,
|
||||
COUNT(
|
||||
DISTINCT tokenId
|
||||
) AS nft_count
|
||||
FROM
|
||||
nft_mints
|
||||
GROUP BY
|
||||
tx_hash
|
||||
),
|
||||
tokens_moved AS (
|
||||
SELECT
|
||||
tx_hash,
|
||||
CONCAT(
|
||||
tx_hash :: STRING,
|
||||
'-',
|
||||
event_index :: STRING
|
||||
) AS _log_id,
|
||||
from_address,
|
||||
to_address,
|
||||
contract_address,
|
||||
raw_amount
|
||||
FROM
|
||||
{{ ref('core__ez_token_transfers') }}
|
||||
WHERE
|
||||
tx_hash IN (
|
||||
SELECT
|
||||
DISTINCT tx_hash
|
||||
FROM
|
||||
nft_mints
|
||||
) qualify(ROW_NUMBER() over(PARTITION BY tx_hash
|
||||
ORDER BY
|
||||
raw_amount DESC)) = 1
|
||||
),
|
||||
token_prices AS (
|
||||
SELECT
|
||||
HOUR,
|
||||
CASE
|
||||
WHEN LOWER(token_address) IS NULL THEN 'ETH'
|
||||
ELSE LOWER(token_address)
|
||||
END AS token_address,
|
||||
price
|
||||
FROM
|
||||
{{ ref('price__ez_prices_hourly') }}
|
||||
WHERE
|
||||
(
|
||||
token_address IN (
|
||||
SELECT
|
||||
DISTINCT LOWER(contract_address)
|
||||
FROM
|
||||
tokens_moved
|
||||
)
|
||||
OR (
|
||||
token_address IS NULL
|
||||
AND symbol IS NULL
|
||||
)
|
||||
OR token_address = '0xc02aaa39b223fe8d0a0e5c4f27ead9083c756cc2'
|
||||
)
|
||||
AND HOUR :: DATE IN (
|
||||
SELECT
|
||||
DISTINCT block_timestamp :: DATE
|
||||
FROM
|
||||
nft_mints
|
||||
)
|
||||
),
|
||||
metadata AS (
|
||||
SELECT
|
||||
LOWER(address) AS address,
|
||||
symbol,
|
||||
NAME,
|
||||
decimals
|
||||
FROM
|
||||
{{ ref('core__dim_contracts') }}
|
||||
WHERE
|
||||
decimals IS NOT NULL
|
||||
),
|
||||
eth_prices AS (
|
||||
SELECT
|
||||
HOUR,
|
||||
token_address,
|
||||
price AS eth_price
|
||||
FROM
|
||||
token_prices
|
||||
WHERE
|
||||
token_address = '0xc02aaa39b223fe8d0a0e5c4f27ead9083c756cc2'
|
||||
),
|
||||
FINAL AS (
|
||||
SELECT
|
||||
block_timestamp,
|
||||
block_number,
|
||||
nft_mints.tx_hash AS tx_hash,
|
||||
event_type,
|
||||
nft_mints.contract_address AS nft_address,
|
||||
project_name,
|
||||
nft_mints.from_address AS nft_from_address,
|
||||
nft_mints.to_address AS nft_to_address,
|
||||
tokenId,
|
||||
erc1155_value,
|
||||
eth_value / nft_count AS mint_price_eth,
|
||||
ROUND(
|
||||
eth_value / nft_count * eth_price,
|
||||
2
|
||||
) AS mint_price_usd,
|
||||
nft_count,
|
||||
raw_amount,
|
||||
CASE
|
||||
WHEN metadata.decimals IS NOT NULL THEN raw_amount / pow(
|
||||
10,
|
||||
metadata.decimals
|
||||
)
|
||||
ELSE raw_amount
|
||||
END AS amount,
|
||||
CASE
|
||||
WHEN metadata.decimals IS NOT NULL THEN amount * price
|
||||
ELSE NULL
|
||||
END AS amount_usd,
|
||||
amount / nft_count AS mint_price_tokens,
|
||||
ROUND(
|
||||
amount_usd / nft_count,
|
||||
2
|
||||
) AS mint_price_tokens_usd,
|
||||
symbol AS mint_token_symbol,
|
||||
tokens_moved.contract_address AS mint_token_address,
|
||||
tx_fee,
|
||||
ROUND(
|
||||
tx_fee * eth_price,
|
||||
2
|
||||
) AS tx_fee_usd,
|
||||
nft_mints._inserted_timestamp,
|
||||
nft_mints._log_id
|
||||
FROM
|
||||
nft_mints
|
||||
JOIN mint_price
|
||||
ON nft_mints.tx_hash = mint_price.tx_hash
|
||||
JOIN tokens_per_tx
|
||||
ON nft_mints.tx_hash = tokens_per_tx.tx_hash
|
||||
LEFT JOIN tokens_moved
|
||||
ON tokens_moved.tx_hash = nft_mints.tx_hash
|
||||
LEFT JOIN token_prices
|
||||
ON DATE_TRUNC(
|
||||
'hour',
|
||||
nft_mints.block_timestamp
|
||||
) = token_prices.hour
|
||||
AND token_prices.token_address = tokens_moved.contract_address
|
||||
LEFT JOIN eth_prices
|
||||
ON DATE_TRUNC(
|
||||
'hour',
|
||||
nft_mints.block_timestamp
|
||||
) = eth_prices.hour
|
||||
LEFT JOIN metadata
|
||||
ON metadata.address = tokens_moved.contract_address
|
||||
WHERE
|
||||
nft_count > 0
|
||||
)
|
||||
SELECT
|
||||
block_timestamp,
|
||||
block_number,
|
||||
tx_hash,
|
||||
event_type,
|
||||
nft_address,
|
||||
project_name,
|
||||
nft_from_address,
|
||||
nft_to_address,
|
||||
tokenId,
|
||||
erc1155_value,
|
||||
mint_price_eth,
|
||||
mint_price_usd,
|
||||
nft_count,
|
||||
amount,
|
||||
amount_usd,
|
||||
mint_price_tokens,
|
||||
mint_price_tokens_usd,
|
||||
mint_token_symbol,
|
||||
mint_token_address,
|
||||
tx_fee,
|
||||
_log_id,
|
||||
_inserted_timestamp,
|
||||
{{ dbt_utils.generate_surrogate_key(
|
||||
['_log_id','nft_address']
|
||||
) }} AS nft_mints_id,
|
||||
SYSDATE() AS inserted_timestamp,
|
||||
SYSDATE() AS modified_timestamp,
|
||||
'{{ invocation_id }}' AS _invocation_id
|
||||
FROM
|
||||
FINAL
|
||||
@ -1,61 +0,0 @@
|
||||
version: 2
|
||||
models:
|
||||
- name: silver__nft_mints
|
||||
tests:
|
||||
- dbt_utils.unique_combination_of_columns:
|
||||
combination_of_columns:
|
||||
- _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: NFT_ADDRESS
|
||||
tests:
|
||||
- not_null
|
||||
- dbt_expectations.expect_column_values_to_match_regex:
|
||||
regex: 0[xX][0-9a-fA-F]+
|
||||
- name: NFT_FROM_ADDRESS
|
||||
tests:
|
||||
- not_null:
|
||||
where: BLOCK_TIMESTAMP > '2021-08-01'
|
||||
- dbt_expectations.expect_column_values_to_match_regex:
|
||||
regex: 0[xX][0-9a-fA-F]+
|
||||
- name: NFT_TO_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: _LOG_ID
|
||||
tests:
|
||||
- not_null
|
||||
- name: _INSERTED_TIMESTAMP
|
||||
tests:
|
||||
- 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
|
||||
@ -1,639 +0,0 @@
|
||||
{{ config(
|
||||
materialized = 'incremental',
|
||||
incremental_strategy = 'delete+insert',
|
||||
unique_key = "block_number",
|
||||
cluster_by = ['block_timestamp::DATE', '_inserted_timestamp::DATE', 'contract_address'],
|
||||
post_hook = "ALTER TABLE {{ this }} ADD SEARCH OPTIMIZATION ON EQUALITY(tx_hash, contract_address, project_name, from_address, to_address, event_type, token_transfer_type), SUBSTRING(project_name, from_address, to_address, event_type, token_transfer_type)",
|
||||
tags = ['silver','nft','curated','heal']
|
||||
) }}
|
||||
|
||||
WITH base AS (
|
||||
|
||||
SELECT
|
||||
CONCAT(
|
||||
tx_hash :: STRING,
|
||||
'-',
|
||||
event_index :: STRING
|
||||
) AS _log_id,
|
||||
block_number,
|
||||
tx_hash,
|
||||
block_timestamp,
|
||||
event_index :: FLOAT AS event_index,
|
||||
contract_address,
|
||||
topics,
|
||||
DATA,
|
||||
regexp_substr_all(SUBSTR(DATA, 3, len(DATA)), '.{64}') AS segmented_data,
|
||||
TO_TIMESTAMP_NTZ(modified_timestamp) AS _inserted_timestamp
|
||||
FROM
|
||||
{{ ref('core__fact_event_logs') }}
|
||||
WHERE
|
||||
tx_succeeded
|
||||
AND (
|
||||
(
|
||||
topics [0] :: STRING = '0xddf252ad1be2c89b69c2b068fc378daa952ba7f163c4a11628f55a4df523b3ef'
|
||||
AND DATA = '0x'
|
||||
AND topics [3] IS NOT NULL
|
||||
) --erc721s TransferSingle event
|
||||
OR (
|
||||
topics [0] :: STRING = '0xc3d58168c5ae7397731d063d5bbf3d657854427343f4c083240f7aacaa2d0f62'
|
||||
) --erc1155s
|
||||
OR (
|
||||
topics [0] :: STRING = '0x4a39dc06d4c0dbc64b70af90fd698a233a518aa5d07e595d983b8c0526c8f7fb'
|
||||
) --erc1155s TransferBatch event
|
||||
OR (
|
||||
topics [0] :: STRING IN (
|
||||
'0xddf252ad1be2c89b69c2b068fc378daa952ba7f163c4a11628f55a4df523b3ef',
|
||||
-- regular transfer topic
|
||||
'0x58e5d5a525e3b40bc15abaa38b5882678db1ee68befd2f60bafe3a7fd06db9e3',
|
||||
-- PunkBought
|
||||
'0x05af636b70da6819000c49f85b21fa82081c632069bb626f30932034099107d8' -- PunkTransfer
|
||||
)
|
||||
AND contract_address IN (
|
||||
'0x6ba6f2207e343923ba692e5cae646fb0f566db8d',
|
||||
-- Old V1
|
||||
'0xb47e3cd837ddf8e4c57f05d70ab865de6e193bbb' -- cryptopunks
|
||||
)
|
||||
) -- cryptopunks
|
||||
OR (
|
||||
topics [0] :: STRING = '0xddf252ad1be2c89b69c2b068fc378daa952ba7f163c4a11628f55a4df523b3ef'
|
||||
AND topics [1] IS NULL
|
||||
)
|
||||
)
|
||||
|
||||
{% if is_incremental() %}
|
||||
AND _inserted_timestamp >= (
|
||||
SELECT
|
||||
MAX(_inserted_timestamp) - INTERVAL '{{ var("LOOKBACK", "4 hours") }}'
|
||||
FROM
|
||||
{{ this }}
|
||||
)
|
||||
{% endif %}
|
||||
),
|
||||
erc721s AS (
|
||||
SELECT
|
||||
_log_id,
|
||||
block_number,
|
||||
tx_hash,
|
||||
block_timestamp,
|
||||
contract_address,
|
||||
CONCAT('0x', SUBSTR(topics [1] :: STRING, 27, 40)) AS from_address,
|
||||
CONCAT('0x', SUBSTR(topics [2] :: STRING, 27, 40)) AS to_address,
|
||||
utils.udf_hex_to_int(
|
||||
topics [3] :: STRING
|
||||
) :: STRING AS token_id,
|
||||
NULL AS erc1155_value,
|
||||
_inserted_timestamp,
|
||||
event_index
|
||||
FROM
|
||||
base
|
||||
WHERE
|
||||
topics [0] :: STRING = '0xddf252ad1be2c89b69c2b068fc378daa952ba7f163c4a11628f55a4df523b3ef'
|
||||
AND DATA = '0x'
|
||||
AND topics [3] IS NOT NULL
|
||||
AND contract_address NOT IN (
|
||||
'0x6ba6f2207e343923ba692e5cae646fb0f566db8d',
|
||||
'0xb47e3cd837ddf8e4c57f05d70ab865de6e193bbb'
|
||||
)
|
||||
),
|
||||
transfer_singles AS (
|
||||
SELECT
|
||||
_log_id,
|
||||
block_number,
|
||||
tx_hash,
|
||||
block_timestamp,
|
||||
contract_address,
|
||||
CONCAT('0x', SUBSTR(topics [1] :: STRING, 27, 40)) AS operator_address,
|
||||
CONCAT('0x', SUBSTR(topics [2] :: STRING, 27, 40)) AS from_address,
|
||||
CONCAT('0x', SUBSTR(topics [3] :: STRING, 27, 40)) AS to_address,
|
||||
utils.udf_hex_to_int(
|
||||
segmented_data [0] :: STRING
|
||||
) :: STRING AS token_id,
|
||||
utils.udf_hex_to_int(
|
||||
segmented_data [1] :: STRING
|
||||
) :: STRING AS erc1155_value,
|
||||
_inserted_timestamp,
|
||||
event_index
|
||||
FROM
|
||||
base
|
||||
WHERE
|
||||
topics [0] :: STRING = '0xc3d58168c5ae7397731d063d5bbf3d657854427343f4c083240f7aacaa2d0f62'
|
||||
AND to_address IS NOT NULL
|
||||
),
|
||||
transfer_batch_raw AS (
|
||||
SELECT
|
||||
block_number,
|
||||
block_timestamp,
|
||||
tx_hash,
|
||||
event_index,
|
||||
segmented_data,
|
||||
CONCAT('0x', SUBSTR(topics [1] :: STRING, 27, 40)) AS operator_address,
|
||||
CONCAT('0x', SUBSTR(topics [2] :: STRING, 27, 40)) AS from_address,
|
||||
CONCAT('0x', SUBSTR(topics [3] :: STRING, 27, 40)) AS to_address,
|
||||
contract_address,
|
||||
utils.udf_hex_to_int(
|
||||
segmented_data [2] :: STRING
|
||||
) tokenid_length,
|
||||
tokenid_length AS quantity_length,
|
||||
_log_id,
|
||||
_inserted_timestamp
|
||||
FROM
|
||||
base
|
||||
WHERE
|
||||
topics [0] :: STRING = '0x4a39dc06d4c0dbc64b70af90fd698a233a518aa5d07e595d983b8c0526c8f7fb'
|
||||
AND to_address IS NOT NULL
|
||||
),
|
||||
flattened AS (
|
||||
SELECT
|
||||
block_number,
|
||||
block_timestamp,
|
||||
_log_id,
|
||||
_inserted_timestamp,
|
||||
tx_hash,
|
||||
event_index,
|
||||
operator_address,
|
||||
from_address,
|
||||
to_address,
|
||||
contract_address,
|
||||
INDEX,
|
||||
VALUE,
|
||||
tokenid_length,
|
||||
quantity_length,
|
||||
2 + tokenid_length AS tokenid_indextag,
|
||||
4 + tokenid_length AS quantity_indextag_start,
|
||||
4 + tokenid_length + tokenid_length AS quantity_indextag_end,
|
||||
CASE
|
||||
WHEN INDEX BETWEEN 3
|
||||
AND (
|
||||
tokenid_indextag
|
||||
) THEN 'tokenid'
|
||||
WHEN INDEX BETWEEN (
|
||||
quantity_indextag_start
|
||||
)
|
||||
AND (
|
||||
quantity_indextag_end
|
||||
) THEN 'quantity'
|
||||
ELSE NULL
|
||||
END AS label
|
||||
FROM
|
||||
transfer_batch_raw,
|
||||
LATERAL FLATTEN (
|
||||
input => segmented_data
|
||||
)
|
||||
),
|
||||
tokenid_list AS (
|
||||
SELECT
|
||||
block_number,
|
||||
block_timestamp,
|
||||
_log_id,
|
||||
_inserted_timestamp,
|
||||
tx_hash,
|
||||
event_index,
|
||||
operator_address,
|
||||
from_address,
|
||||
to_address,
|
||||
contract_address,
|
||||
utils.udf_hex_to_int(
|
||||
VALUE :: STRING
|
||||
) :: STRING AS tokenId,
|
||||
ROW_NUMBER() over (
|
||||
PARTITION BY tx_hash,
|
||||
event_index
|
||||
ORDER BY
|
||||
INDEX ASC
|
||||
) AS tokenid_order
|
||||
FROM
|
||||
flattened
|
||||
WHERE
|
||||
label = 'tokenid'
|
||||
),
|
||||
quantity_list AS (
|
||||
SELECT
|
||||
tx_hash,
|
||||
event_index,
|
||||
utils.udf_hex_to_int(
|
||||
VALUE :: STRING
|
||||
) :: STRING AS quantity,
|
||||
ROW_NUMBER() over (
|
||||
PARTITION BY tx_hash,
|
||||
event_index
|
||||
ORDER BY
|
||||
INDEX ASC
|
||||
) AS quantity_order
|
||||
FROM
|
||||
flattened
|
||||
WHERE
|
||||
label = 'quantity'
|
||||
),
|
||||
transfer_batch_final AS (
|
||||
SELECT
|
||||
block_number,
|
||||
block_timestamp,
|
||||
_log_id,
|
||||
_inserted_timestamp,
|
||||
t.tx_hash,
|
||||
t.event_index,
|
||||
operator_address,
|
||||
from_address,
|
||||
to_address,
|
||||
contract_address,
|
||||
t.tokenId AS token_id,
|
||||
q.quantity AS erc1155_value,
|
||||
tokenid_order AS intra_event_index
|
||||
FROM
|
||||
tokenid_list t
|
||||
INNER JOIN quantity_list q
|
||||
ON t.tx_hash = q.tx_hash
|
||||
AND t.event_index = q.event_index
|
||||
AND t.tokenid_order = q.quantity_order
|
||||
),
|
||||
punks_bought_raw AS (
|
||||
-- punks bought via sale or bids
|
||||
SELECT
|
||||
_log_id,
|
||||
block_number,
|
||||
tx_hash,
|
||||
block_timestamp,
|
||||
contract_address,
|
||||
topics,
|
||||
utils.udf_hex_to_int(
|
||||
topics [1] :: STRING
|
||||
) :: STRING AS token_id,
|
||||
CONCAT('0x', SUBSTR(topics [2] :: STRING, 27, 40)) AS from_address,
|
||||
CONCAT('0x', SUBSTR(topics [3] :: STRING, 27, 40)) AS to_address,
|
||||
NULL AS erc1155_value,
|
||||
LAG(topics) over (
|
||||
PARTITION BY tx_hash
|
||||
ORDER BY
|
||||
event_index ASC
|
||||
) AS prev_topics,
|
||||
CONCAT('0x', SUBSTR(prev_topics [1] :: STRING, 27, 40)) AS prev_from_address,
|
||||
CONCAT('0x', SUBSTR(prev_topics [2] :: STRING, 27, 40)) AS prev_to_address,
|
||||
_inserted_timestamp,
|
||||
event_index
|
||||
FROM
|
||||
base
|
||||
WHERE
|
||||
topics [0] :: STRING IN (
|
||||
'0x58e5d5a525e3b40bc15abaa38b5882678db1ee68befd2f60bafe3a7fd06db9e3',
|
||||
-- punk bought
|
||||
'0xddf252ad1be2c89b69c2b068fc378daa952ba7f163c4a11628f55a4df523b3ef' -- transfer
|
||||
)
|
||||
),
|
||||
punks_bought AS (
|
||||
SELECT
|
||||
_log_id,
|
||||
block_number,
|
||||
tx_hash,
|
||||
block_timestamp,
|
||||
contract_address,
|
||||
token_id,
|
||||
from_address,
|
||||
CASE
|
||||
WHEN to_address = '0x0000000000000000000000000000000000000000'
|
||||
AND prev_topics [0] :: STRING = '0xddf252ad1be2c89b69c2b068fc378daa952ba7f163c4a11628f55a4df523b3ef'
|
||||
AND prev_from_address = from_address THEN prev_to_address
|
||||
ELSE to_address
|
||||
END AS to_address,
|
||||
erc1155_value,
|
||||
IFF(
|
||||
to_address = '0x0000000000000000000000000000000000000000',
|
||||
'bid_won',
|
||||
'sale'
|
||||
) AS transfer_type,
|
||||
_inserted_timestamp,
|
||||
event_index
|
||||
FROM
|
||||
punks_bought_raw
|
||||
WHERE
|
||||
topics [0] :: STRING = '0x58e5d5a525e3b40bc15abaa38b5882678db1ee68befd2f60bafe3a7fd06db9e3'
|
||||
),
|
||||
punks_transfer AS (
|
||||
SELECT
|
||||
_log_id,
|
||||
block_number,
|
||||
tx_hash,
|
||||
block_timestamp,
|
||||
contract_address,
|
||||
utils.udf_hex_to_int(
|
||||
DATA :: STRING
|
||||
) :: STRING AS token_id,
|
||||
CONCAT('0x', SUBSTR(topics [1] :: STRING, 27, 40)) AS from_address,
|
||||
CONCAT('0x', SUBSTR(topics [2] :: STRING, 27, 40)) AS to_address,
|
||||
NULL AS erc1155_value,
|
||||
_inserted_timestamp,
|
||||
event_index
|
||||
FROM
|
||||
base
|
||||
WHERE
|
||||
topics [0] :: STRING = '0x05af636b70da6819000c49f85b21fa82081c632069bb626f30932034099107d8'
|
||||
),
|
||||
legacy_tokens AS (
|
||||
SELECT
|
||||
_log_id,
|
||||
block_number,
|
||||
tx_hash,
|
||||
block_timestamp,
|
||||
contract_address,
|
||||
CONCAT('0x', SUBSTR(segmented_data [0], 25, 40)) AS from_address,
|
||||
CONCAT('0x', SUBSTR(segmented_data [1], 25, 40)) AS to_address,
|
||||
utils.udf_hex_to_int(
|
||||
segmented_data [2] :: STRING
|
||||
) :: STRING AS token_id,
|
||||
NULL AS erc1155_value,
|
||||
_inserted_timestamp,
|
||||
event_index
|
||||
FROM
|
||||
base
|
||||
WHERE
|
||||
topics [0] :: STRING = '0xddf252ad1be2c89b69c2b068fc378daa952ba7f163c4a11628f55a4df523b3ef'
|
||||
AND topics [1] IS NULL
|
||||
),
|
||||
all_transfers AS (
|
||||
SELECT
|
||||
block_number,
|
||||
tx_hash,
|
||||
block_timestamp,
|
||||
contract_address,
|
||||
from_address,
|
||||
to_address,
|
||||
token_id,
|
||||
erc1155_value,
|
||||
_inserted_timestamp,
|
||||
event_index,
|
||||
1 AS intra_event_index,
|
||||
'erc721_Transfer' AS token_transfer_type,
|
||||
CONCAT(
|
||||
_log_id,
|
||||
'-',
|
||||
contract_address,
|
||||
'-',
|
||||
token_id
|
||||
) AS _log_id
|
||||
FROM
|
||||
erc721s
|
||||
UNION ALL
|
||||
SELECT
|
||||
block_number,
|
||||
tx_hash,
|
||||
block_timestamp,
|
||||
contract_address,
|
||||
from_address,
|
||||
to_address,
|
||||
token_id,
|
||||
erc1155_value,
|
||||
_inserted_timestamp,
|
||||
event_index,
|
||||
1 AS intra_event_index,
|
||||
'erc1155_TransferSingle' AS token_transfer_type,
|
||||
CONCAT(
|
||||
_log_id,
|
||||
'-',
|
||||
contract_address,
|
||||
'-',
|
||||
token_id
|
||||
) AS _log_id
|
||||
FROM
|
||||
transfer_singles
|
||||
WHERE
|
||||
erc1155_value != '0'
|
||||
UNION ALL
|
||||
SELECT
|
||||
block_number,
|
||||
tx_hash,
|
||||
block_timestamp,
|
||||
contract_address,
|
||||
from_address,
|
||||
to_address,
|
||||
token_id,
|
||||
erc1155_value,
|
||||
_inserted_timestamp,
|
||||
event_index,
|
||||
intra_event_index,
|
||||
'erc1155_TransferBatch' AS token_transfer_type,
|
||||
CONCAT(
|
||||
_log_id,
|
||||
'-',
|
||||
contract_address,
|
||||
'-',
|
||||
token_id,
|
||||
'-',
|
||||
intra_event_index
|
||||
) AS _log_id
|
||||
FROM
|
||||
transfer_batch_final
|
||||
WHERE
|
||||
erc1155_value != '0'
|
||||
UNION ALL
|
||||
SELECT
|
||||
block_number,
|
||||
tx_hash,
|
||||
block_timestamp,
|
||||
contract_address,
|
||||
from_address,
|
||||
to_address,
|
||||
token_id,
|
||||
erc1155_value,
|
||||
_inserted_timestamp,
|
||||
event_index,
|
||||
1 AS intra_event_index,
|
||||
IFF(
|
||||
transfer_type = 'sale',
|
||||
'erc20_punks_sale',
|
||||
'erc20_punks_bidwon'
|
||||
) AS token_transfer_type,
|
||||
CONCAT(
|
||||
_log_id,
|
||||
'-',
|
||||
contract_address,
|
||||
'-',
|
||||
token_id
|
||||
) AS _log_id
|
||||
FROM
|
||||
punks_bought
|
||||
UNION ALL
|
||||
SELECT
|
||||
block_number,
|
||||
tx_hash,
|
||||
block_timestamp,
|
||||
contract_address,
|
||||
from_address,
|
||||
to_address,
|
||||
token_id,
|
||||
erc1155_value,
|
||||
_inserted_timestamp,
|
||||
event_index,
|
||||
1 AS intra_event_index,
|
||||
'erc20_punks_transfer' AS token_transfer_type,
|
||||
CONCAT(
|
||||
_log_id,
|
||||
'-',
|
||||
contract_address,
|
||||
'-',
|
||||
token_id
|
||||
) AS _log_id
|
||||
FROM
|
||||
punks_transfer
|
||||
UNION ALL
|
||||
SELECT
|
||||
block_number,
|
||||
tx_hash,
|
||||
block_timestamp,
|
||||
contract_address,
|
||||
from_address,
|
||||
to_address,
|
||||
token_id,
|
||||
erc1155_value,
|
||||
_inserted_timestamp,
|
||||
event_index,
|
||||
1 AS intra_event_index,
|
||||
'erc721_legacy_Transfer' AS token_transfer_type,
|
||||
CONCAT(
|
||||
_log_id,
|
||||
'-',
|
||||
contract_address,
|
||||
'-',
|
||||
token_id
|
||||
) AS _log_id
|
||||
FROM
|
||||
legacy_tokens
|
||||
),
|
||||
transfer_base AS (
|
||||
SELECT
|
||||
block_number,
|
||||
block_timestamp,
|
||||
tx_hash,
|
||||
event_index,
|
||||
intra_event_index,
|
||||
contract_address,
|
||||
C.name AS project_name,
|
||||
from_address,
|
||||
to_address,
|
||||
A.token_id AS tokenId,
|
||||
erc1155_value,
|
||||
CASE
|
||||
WHEN from_address = '0x0000000000000000000000000000000000000000' THEN 'mint'
|
||||
ELSE 'other'
|
||||
END AS event_type,
|
||||
token_transfer_type,
|
||||
A._log_id,
|
||||
A._inserted_timestamp
|
||||
FROM
|
||||
all_transfers A
|
||||
LEFT JOIN {{ ref('core__dim_contracts') }} C
|
||||
ON A.contract_address = C.address
|
||||
WHERE
|
||||
to_address IS NOT NULL
|
||||
)
|
||||
|
||||
{% if is_incremental() and var(
|
||||
'HEAL_MODEL'
|
||||
) %},
|
||||
heal_model AS (
|
||||
SELECT
|
||||
block_number,
|
||||
block_timestamp,
|
||||
tx_hash,
|
||||
event_index,
|
||||
intra_event_index,
|
||||
contract_address,
|
||||
C.name AS project_name,
|
||||
from_address,
|
||||
to_address,
|
||||
tokenId,
|
||||
erc1155_value,
|
||||
event_type,
|
||||
token_transfer_type,
|
||||
_log_id,
|
||||
t._inserted_timestamp
|
||||
FROM
|
||||
{{ this }}
|
||||
t
|
||||
LEFT JOIN {{ ref('core__dim_contracts') }} C
|
||||
ON t.contract_address = C.address
|
||||
WHERE
|
||||
t.block_number IN (
|
||||
SELECT
|
||||
DISTINCT t1.block_number AS block_number
|
||||
FROM
|
||||
{{ this }}
|
||||
t1
|
||||
WHERE
|
||||
t1.project_name IS NULL
|
||||
AND _inserted_timestamp < (
|
||||
SELECT
|
||||
MAX(
|
||||
_inserted_timestamp
|
||||
) - INTERVAL '{{ var("LOOKBACK", "4 hours") }}'
|
||||
FROM
|
||||
{{ this }}
|
||||
)
|
||||
AND EXISTS (
|
||||
SELECT
|
||||
1
|
||||
FROM
|
||||
{{ ref('core__dim_contracts') }} C
|
||||
WHERE
|
||||
C.modified_timestamp > DATEADD('DAY', -14, SYSDATE())
|
||||
AND C.name IS NOT NULL
|
||||
AND C.address = t1.contract_address)
|
||||
)
|
||||
)
|
||||
{% endif %}
|
||||
SELECT
|
||||
block_number,
|
||||
block_timestamp,
|
||||
tx_hash,
|
||||
event_index,
|
||||
intra_event_index,
|
||||
contract_address,
|
||||
A.project_name,
|
||||
from_address,
|
||||
to_address,
|
||||
tokenId,
|
||||
erc1155_value,
|
||||
event_type,
|
||||
token_transfer_type,
|
||||
_log_id,
|
||||
A._inserted_timestamp,
|
||||
{{ dbt_utils.generate_surrogate_key(
|
||||
['tx_hash','event_index','intra_event_index']
|
||||
) }} AS nft_transfers_id,
|
||||
SYSDATE() AS inserted_timestamp,
|
||||
SYSDATE() AS modified_timestamp,
|
||||
'{{ invocation_id }}' AS _invocation_id
|
||||
FROM
|
||||
transfer_base A qualify ROW_NUMBER() over (
|
||||
PARTITION BY _log_id
|
||||
ORDER BY
|
||||
A._inserted_timestamp DESC
|
||||
) = 1
|
||||
|
||||
{% if is_incremental() and var(
|
||||
'HEAL_MODEL'
|
||||
) %}
|
||||
UNION ALL
|
||||
SELECT
|
||||
block_number,
|
||||
block_timestamp,
|
||||
tx_hash,
|
||||
event_index,
|
||||
intra_event_index,
|
||||
contract_address,
|
||||
project_name,
|
||||
from_address,
|
||||
to_address,
|
||||
tokenId,
|
||||
erc1155_value,
|
||||
event_type,
|
||||
token_transfer_type,
|
||||
_log_id,
|
||||
_inserted_timestamp,
|
||||
{{ dbt_utils.generate_surrogate_key(
|
||||
['tx_hash','event_index','intra_event_index']
|
||||
) }} AS nft_transfers_id,
|
||||
SYSDATE() AS inserted_timestamp,
|
||||
SYSDATE() AS modified_timestamp,
|
||||
'{{ invocation_id }}' AS _invocation_id
|
||||
FROM
|
||||
heal_model
|
||||
{% endif %}
|
||||
@ -1,67 +0,0 @@
|
||||
version: 2
|
||||
models:
|
||||
- name: silver__nft_transfers
|
||||
tests:
|
||||
- dbt_utils.unique_combination_of_columns:
|
||||
combination_of_columns:
|
||||
- _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: EVENT_INDEX
|
||||
tests:
|
||||
- not_null
|
||||
- name: INTRA_EVENT_INDEX
|
||||
tests:
|
||||
- not_null
|
||||
- name: CONTRACT_ADDRESS
|
||||
tests:
|
||||
- not_null
|
||||
- dbt_expectations.expect_column_values_to_match_regex:
|
||||
regex: 0[xX][0-9a-fA-F]+
|
||||
- name: FROM_ADDRESS
|
||||
tests:
|
||||
- not_null:
|
||||
where: BLOCK_TIMESTAMP > '2021-08-01'
|
||||
- dbt_expectations.expect_column_values_to_match_regex:
|
||||
regex: 0[xX][0-9a-fA-F]+
|
||||
- name: TO_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: _LOG_ID
|
||||
tests:
|
||||
- not_null
|
||||
- name: _INSERTED_TIMESTAMP
|
||||
tests:
|
||||
- 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
|
||||
Loading…
Reference in New Issue
Block a user