Avax_Two_New_Views (#5)

* Avax_Two_New_Views

* updates

Co-authored-by: austinFlipside <austin@flipsidecrypto.com>
This commit is contained in:
robel91 2022-06-27 14:31:03 -04:00 committed by GitHub
parent 77a6c44be8
commit aee75dc5c7
No known key found for this signature in database
GPG Key ID: 4AEE18F83AFDEB23
27 changed files with 448 additions and 3 deletions

File diff suppressed because one or more lines are too long

File diff suppressed because one or more lines are too long

View File

@ -0,0 +1,5 @@
{% docs avax_eth_amount %}
ETH value transferred.
{% enddocs %}

View File

@ -0,0 +1,6 @@
{% docs avax_eth_amount_usd %}
ETH value transferred, in USD.
{% enddocs %}

View File

@ -0,0 +1,5 @@
{% docs avax_ez_eth_transfers_table_doc %}
This table contains all native ETH transfers, including equivalent USD amounts. The origin addresses correspond to the to and from addresses from the `fact_transactions` table. The `identifier` and `tx_hash` columns relate this table back to `fact_traces`, which contains more details on the transfers.
{% enddocs %}

View File

@ -0,0 +1,5 @@
{% docs avax_ez_transfer_table_doc %}
This table will contain all events in the ```fact_token_transfers table```, along with joined columns such as token price, symbol, and decimals where possible that allow for easier analysis of token transfer events. Please note Native ETH transfers are not included here.
{% enddocs %}

View File

@ -0,0 +1,5 @@
{% docs avax_log_id_transfers %}
This is the primary key for this table. This is a concatenation of the transaction hash and the event index at which the transfer event occurred. This field can be used to find more details on the event within the ```fact_event_logs``` table.
{% enddocs %}

View File

@ -0,0 +1,5 @@
{% docs avax_eth_origin_from %}
The from address at the transaction level.
{% enddocs %}

View File

@ -0,0 +1,5 @@
{% docs avax_eth_origin_to %}
The to address at the transaction level.
{% enddocs %}

View File

@ -0,0 +1,5 @@
{% docs avax_transfer_amount %}
The decimal transformed amount for this token. Tokens without a decimal adjustment will be nulled out here.
{% enddocs %}

View File

@ -0,0 +1,5 @@
{% docs avax_transfer_amount_usd %}
The amount in US dollars for this transfer at the time of the transfer. Tokens without a decimal adjustment or price will be nulled out here.
{% enddocs %}

View File

@ -0,0 +1,5 @@
{% docs avax_transfer_contract_address %}
Contract address of the token being transferred.
{% enddocs %}

View File

@ -0,0 +1,5 @@
{% docs avax_transfer_from_address %}
The sending address of this transfer.
{% enddocs %}

View File

@ -0,0 +1,5 @@
{% docs avax_transfer_has_decimal %}
Whether or not our contracts model contains the necessary decimal adjustment for this token.
{% enddocs %}

View File

@ -0,0 +1,5 @@
{% docs avax_transfer_has_price %}
Whether or not our prices model contains this hourly token price.
{% enddocs %}

View File

@ -0,0 +1,5 @@
{% docs avax_transfer_raw_amount %}
The amount of tokens transferred. This value is not decimal adjusted.
{% enddocs %}

View File

@ -0,0 +1,5 @@
{% docs avax_transfer_table_doc %}
This table contains events on the Ethereum Blockchain with an event name of 'Transfer'. The contract address is the token transferred, and the raw amount field is the amount of tokens transferred. Please note this amount is not decimal adjusted. Decimal adjustments for a token address can be found in ```dim_contracts```. This table will not contain transfers of native ETH.
{% enddocs %}

View File

@ -0,0 +1,5 @@
{% docs avax_transfer_to_address %}
The receiving address of this transfer. This can be a contract address.
{% enddocs %}

View File

@ -0,0 +1,5 @@
{% docs avax_transfer_token_price %}
The price, if available, for this token at the transfer time.
{% enddocs %}

View File

@ -0,0 +1,5 @@
{% docs avax_transfer_tx_hash %}
Transaction hash is a unique 66-character identifier that is generated when a transaction is executed. This will not be unique in this table as a transaction could include multiple transfer events.
{% enddocs %}

View File

@ -0,0 +1,63 @@
{{ config(
materialized = 'view'
) }}
WITH eth_base AS (
SELECT
tx_hash,
block_number,
block_timestamp,
from_address,
to_address,
eth_value,
identifier,
_call_id,
ingested_at,
input
FROM
{{ ref('silver__traces') }}
WHERE
eth_value > 0
AND tx_status = 'SUCCESS'
AND gas_used IS NOT NULL
),
eth_price AS (
SELECT
HOUR,
AVG(price) AS eth_price
FROM
{{ source(
'ethereum',
'fact_hourly_token_prices'
) }}
WHERE
token_address = LOWER('0x85f138bfEE4ef8e540890CFb48F620571d67Eda3')
GROUP BY
HOUR
)
SELECT
A.tx_hash AS tx_hash,
A.block_number AS block_number,
A.block_timestamp AS block_timestamp,
A.identifier AS identifier,
tx.from_address AS origin_from_address,
tx.to_address AS origin_to_address,
tx.origin_function_signature AS origin_function_signature,
A.from_address AS eth_from_address,
A.to_address AS eth_to_address,
A.eth_value AS amount,
ROUND(
A.eth_value * eth_price,
2
) AS amount_usd
FROM
eth_base A
LEFT JOIN eth_price
ON DATE_TRUNC(
'hour',
block_timestamp
) = HOUR
JOIN {{ ref('silver__transactions') }}
tx
ON A.tx_hash = tx.tx_hash

View File

@ -0,0 +1,32 @@
version: 2
models:
- name: core__ez_avax_transfers
description: '{{ doc("avax_ez_transfer_table_doc") }}'
columns:
- name: BLOCK_NUMBER
description: '{{ doc("avax_block_number") }}'
- name: BLOCK_TIMESTAMP
description: '{{ doc("avax_block_timestamp") }}'
- name: TX_HASH
description: '{{ doc("avax_transfer_tx_hash") }}'
- name: ETH_FROM_ADDRESS
description: '{{ doc("avax_transfer_from_address") }}'
- name: ETH_TO_ADDRESS
description: '{{ doc("avax_transfer_to_address") }}'
- name: AMOUNT
description: '{{ doc("avax_eth_amount") }}'
- name: TOKEN_PRICE
description: '{{ doc("avax_transfer_token_price") }}'
- name: AMOUNT_USD
description: '{{ doc("avax_eth_amount_usd") }}'
- name: HAS_PRICE
description: '{{ doc("avax_transfer_has_price") }}'
- name: ORIGIN_FUNCTION_SIGNATURE
description: '{{ doc("avax_origin_sig") }}'
- name: ORIGIN_FROM_ADDRESS
description: '{{ doc("avax_origin_from") }}'
- name: ORIGIN_TO_ADDRESS
description: '{{ doc("avax_origin_to") }}'
- name: IDENTIFIER
description: '{{ doc("avax_traces_identifier") }}'

View File

@ -0,0 +1,20 @@
{{ config(
materialized = 'view',
persist_docs ={ "relation": true,
"columns": true }
) }}
SELECT
block_number,
block_timestamp,
tx_hash,
origin_function_signature,
origin_from_address,
origin_to_address,
contract_address,
from_address,
to_address,
raw_amount,
_log_id
FROM
{{ ref('silver__transfers') }}

View File

@ -0,0 +1,28 @@
version: 2
models:
- name: core__fact_token_transfers
description: '{{ doc("avax_transfer_table_doc") }}'
columns:
- name: BLOCK_NUMBER
description: '{{ doc("avax_block_number") }}'
- name: BLOCK_TIMESTAMP
description: '{{ doc("avax_block_timestamp") }}'
- name: TX_HASH
description: '{{ doc("avax_transfer_tx_hash") }}'
- name: CONTRACT_ADDRESS
description: '{{ doc("avax_transfer_contract_address") }}'
- name: FROM_ADDRESS
description: '{{ doc("avax_transfer_from_address") }}'
- name: TO_ADDRESS
description: '{{ doc("avax_transfer_to_address") }}'
- name: RAW_AMOUNT
description: '{{ doc("avax_transfer_raw_amount") }}'
- name: _LOG_ID
description: '{{ doc("avax_log_id_transfers") }}'
- name: ORIGIN_FUNCTION_SIGNATURE
description: '{{ doc("avax_origin_sig") }}'
- name: ORIGIN_FROM_ADDRESS
description: '{{ doc("avax_origin_from") }}'
- name: ORIGIN_TO_ADDRESS
description: '{{ doc("avax_origin_to") }}'

View File

@ -0,0 +1,140 @@
{{ config(
materialized = 'incremental',
unique_key = '_log_id',
cluster_by = ['_inserted_timestamp::DATE']
) }}
WITH logs AS (
SELECT
_log_id,
block_number,
block_timestamp,
tx_hash,
origin_function_signature,
origin_from_address,
origin_to_address,
contract_address,
event_name,
event_index,
event_inputs,
topics,
DATA,
_inserted_timestamp :: TIMESTAMP AS _inserted_timestamp
FROM
{{ ref('silver__logs') }}
WHERE
tx_status = 'SUCCESS'
{% if is_incremental() %}
AND _inserted_timestamp >= (
SELECT
MAX(
_inserted_timestamp
)
FROM
{{ this }}
)
{% endif %}
),
transfers AS (
SELECT
_log_id,
block_number,
tx_hash,
block_timestamp,
origin_function_signature,
origin_from_address,
origin_to_address,
contract_address :: STRING AS contract_address,
event_inputs :from :: STRING AS from_address,
event_inputs :to :: STRING AS to_address,
event_inputs :value :: FLOAT AS raw_amount,
event_index,
_inserted_timestamp
FROM
logs
WHERE
event_name = 'Transfer'
AND raw_amount IS NOT NULL
),
find_missing_events AS (
SELECT
_log_id,
block_number,
tx_hash,
block_timestamp,
origin_function_signature,
origin_from_address,
origin_to_address,
contract_address :: STRING AS contract_address,
CONCAT('0x', SUBSTR(topics [1], 27, 40)) :: STRING AS from_address,
CONCAT('0x', SUBSTR(topics [2], 27, 40)) :: STRING AS to_address,
COALESCE(udf_hex_to_int(topics [3] :: STRING), udf_hex_to_int(SUBSTR(DATA, 3, 64))) :: FLOAT AS raw_amount,
event_index,
_inserted_timestamp
FROM
logs
WHERE
event_name IS NULL
AND contract_address IN (
SELECT
DISTINCT contract_address
FROM
transfers
)
AND topics [0] :: STRING = '0xddf252ad1be2c89b69c2b068fc378daa952ba7f163c4a11628f55a4df523b3ef'
),
all_transfers AS (
SELECT
_log_id,
tx_hash,
block_number,
block_timestamp,
origin_function_signature,
origin_from_address,
origin_to_address,
contract_address,
from_address,
to_address,
raw_amount,
event_index,
_inserted_timestamp
FROM
transfers
UNION ALL
SELECT
_log_id,
tx_hash,
block_number,
block_timestamp,
origin_function_signature,
origin_from_address,
origin_to_address,
contract_address,
from_address,
to_address,
raw_amount,
event_index,
_inserted_timestamp
FROM
find_missing_events
)
SELECT
_log_id,
block_number,
tx_hash,
origin_function_signature,
origin_from_address,
origin_to_address,
block_timestamp,
contract_address,
from_address,
to_address,
raw_amount,
_inserted_timestamp,
event_index
FROM
all_transfers qualify(ROW_NUMBER() over(PARTITION BY _log_id
ORDER BY
_inserted_timestamp DESC)) = 1

View File

@ -0,0 +1,67 @@
version: 2
models:
- name: silver__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_NTZ
- name: TX_HASH
tests:
- not_null
- dbt_expectations.expect_column_values_to_match_regex:
regex: 0[xX][0-9a-fA-F]+
- 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: RAW_AMOUNT
tests:
- not_null
- dbt_expectations.expect_column_values_to_be_in_type_list:
column_type_list:
- NUMBER
- FLOAT
- name: _LOG_ID
tests:
- not_null
- name: ORIGIN_FUNCTION_SIGNATURE
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:
- dbt_expectations.expect_column_values_to_match_regex:
regex: 0[xX][0-9a-fA-F]+

View File

@ -12,4 +12,8 @@ sources:
schema: crosschain
tables:
- name: address_labels
- name: ethereum
database: ethereum
schema: core
tables:
- name: fact_hourly_token_prices