Skip to content
New issue

Have a question about this project? Sign up for a free GitHub account to open an issue and contact its maintainers and the community.

By clicking “Sign up for GitHub”, you agree to our terms of service and privacy statement. We’ll occasionally send you account related emails.

Already on GitHub? Sign in to your account

New Event Models for GMX v2 (next iteration) #7314

Original file line number Diff line number Diff line change
@@ -0,0 +1,195 @@
{{
config(
schema = 'gmx_v2_arbitrum',
alias = 'claimable_funding_amount_per_size_updated',
materialized = 'incremental',
unique_key = ['tx_hash', 'index'],
incremental_strategy = 'merge'
)
}}

{%- set event_name = 'ClaimableFundingAmountPerSizeUpdated' -%}
{%- set blockchain_name = 'arbitrum' -%}


WITH evt_data_1 AS (
SELECT
-- Main Variables
'{{ blockchain_name }}' AS blockchain,
evt_block_time AS block_time,
evt_block_number AS block_number,
evt_tx_hash AS tx_hash,
evt_index AS index,
contract_address,
eventName AS event_name,
eventData AS data,
msgSender AS msg_sender
FROM {{ source('gmx_v2_arbitrum','EventEmitter_evt_EventLog1')}}
WHERE eventName = '{{ event_name }}'
{% if is_incremental() %}
AND {{ incremental_predicate('evt_block_time') }}
{% endif %}
)

, evt_data_2 AS (
SELECT
-- Main Variables
'{{ blockchain_name }}' AS blockchain,
evt_block_time AS block_time,
evt_block_number AS block_number,
evt_tx_hash AS tx_hash,
evt_index AS index,
contract_address,
eventName AS event_name,
eventData AS data,
msgSender AS msg_sender
FROM {{ source('gmx_v2_arbitrum','EventEmitter_evt_EventLog2')}}
WHERE eventName = '{{ event_name }}'
{% if is_incremental() %}
AND {{ incremental_predicate('evt_block_time') }}
{% endif %}
)

-- unite 2 tables
, evt_data AS (
SELECT *
FROM evt_data_1
UNION ALL
SELECT *
FROM evt_data_2
)

, parsed_data AS (
SELECT
tx_hash,
index,
json_query(data, 'lax $.addressItems' OMIT QUOTES) AS address_items,
json_query(data, 'lax $.uintItems' OMIT QUOTES) AS uint_items,
json_query(data, 'lax $.boolItems' OMIT QUOTES) AS bool_items
FROM
evt_data
)

, address_items_parsed AS (
SELECT
tx_hash,
index,
json_extract_scalar(CAST(item AS VARCHAR), '$.key') AS key_name,
json_extract_scalar(CAST(item AS VARCHAR), '$.value') AS value
FROM
parsed_data,
UNNEST(
CAST(json_extract(address_items, '$.items') AS ARRAY(JSON))
) AS t(item)
)

, uint_items_parsed AS (
SELECT
tx_hash,
index,
json_extract_scalar(CAST(item AS VARCHAR), '$.key') AS key_name,
json_extract_scalar(CAST(item AS VARCHAR), '$.value') AS value
FROM
parsed_data,
UNNEST(
CAST(json_extract(uint_items, '$.items') AS ARRAY(JSON))
) AS t(item)
)

, bool_items_parsed AS (
SELECT
tx_hash,
index,
json_extract_scalar(CAST(item AS VARCHAR), '$.key') AS key_name,
json_extract_scalar(CAST(item AS VARCHAR), '$.value') AS value
FROM
parsed_data,
UNNEST(
CAST(json_extract(bool_items, '$.items') AS ARRAY(JSON))
) AS t(item)
)

, combined AS (
SELECT *
FROM address_items_parsed
UNION ALL
SELECT *
FROM uint_items_parsed
UNION ALL
SELECT *
FROM bool_items_parsed
)

, evt_data_parsed AS (
SELECT
tx_hash,
index,

MAX(CASE WHEN key_name = 'market' THEN value END) AS market,
MAX(CASE WHEN key_name = 'collateralToken' THEN value END) AS collateral_token,
MAX(CASE WHEN key_name = 'delta' THEN value END) AS delta,
MAX(CASE WHEN key_name = 'value' THEN value END) AS "value",
MAX(CASE WHEN key_name = 'isLong' THEN value END) AS is_long

FROM
combined
GROUP BY tx_hash, index
)

, event_data AS (
SELECT
blockchain,
block_time,
DATE(block_time) AS block_date,
block_number,
ED.tx_hash,
ED.index,
contract_address,
event_name,
msg_sender,

from_hex(market) AS market,
from_hex(collateral_token) AS collateral_token,
TRY_CAST(delta AS DOUBLE) delta,
TRY_CAST("value" AS DOUBLE) "value",
TRY_CAST(is_long AS BOOLEAN) AS is_long

FROM evt_data AS ED
LEFT JOIN evt_data_parsed AS EDP
ON ED.tx_hash = EDP.tx_hash
AND ED.index = EDP.index
)

, full_data AS (
SELECT
blockchain,
block_time,
DATE(block_time) AS block_date,
block_number,
tx_hash,
index,
contract_address,
event_name,
msg_sender,

market,
ED.collateral_token,
delta / POWER(10, CTD.collateral_token_decimals + 15) AS delta,
"value" / POWER(10, CTD.collateral_token_decimals + 15) AS "value",
is_long

FROM event_data AS ED
LEFT JOIN gmx_v2_arbitrum.collateral_tokens_data AS CTD
ON ED.collateral_token = CTD.collateral_token
)

--can be removed once decoded tables are fully denormalized
{{
add_tx_columns(
model_cte = 'full_data'
, blockchain = blockchain_name
, columns = ['from', 'to']
)
}}


Original file line number Diff line number Diff line change
@@ -0,0 +1,187 @@
{{
config(
schema = 'gmx_v2_arbitrum',
alias = 'deposit_cancelled',
materialized = 'incremental',
unique_key = ['tx_hash', 'index'],
incremental_strategy = 'merge'
)
}}

{%- set event_name = 'DepositCancelled' -%}
{%- set blockchain_name = 'arbitrum' -%}


WITH evt_data_1 AS (
SELECT
-- Main Variables
'{{ blockchain_name }}' AS blockchain,
evt_block_time AS block_time,
evt_block_number AS block_number,
evt_tx_hash AS tx_hash,
evt_index AS index,
contract_address,
eventName AS event_name,
eventData AS data,
msgSender AS msg_sender
FROM {{ source('gmx_v2_arbitrum','EventEmitter_evt_EventLog1')}}
WHERE eventName = '{{ event_name }}'
{% if is_incremental() %}
AND {{ incremental_predicate('evt_block_time') }}
{% endif %}
)

, evt_data_2 AS (
SELECT
-- Main Variables
'{{ blockchain_name }}' AS blockchain,
evt_block_time AS block_time,
evt_block_number AS block_number,
evt_tx_hash AS tx_hash,
evt_index AS index,
contract_address,
eventName AS event_name,
eventData AS data,
msgSender AS msg_sender
FROM {{ source('gmx_v2_arbitrum','EventEmitter_evt_EventLog2')}}
WHERE eventName = '{{ event_name }}'
{% if is_incremental() %}
AND {{ incremental_predicate('evt_block_time') }}
{% endif %}
)

-- unite 2 tables
, evt_data AS (
SELECT *
FROM evt_data_1
UNION ALL
SELECT *
FROM evt_data_2
)

, parsed_data AS (
SELECT
tx_hash,
index,
json_query(data, 'lax $.addressItems' OMIT QUOTES) AS address_items,
json_query(data, 'lax $.bytes32Items' OMIT QUOTES) AS bytes32_items,
json_query(data, 'lax $.bytesItems' OMIT QUOTES) AS bytes_items,
json_query(data, 'lax $.stringItems' OMIT QUOTES) AS string_items
FROM
evt_data
)

, address_items_parsed AS (
SELECT
tx_hash,
index,
json_extract_scalar(CAST(item AS VARCHAR), '$.key') AS key_name,
json_extract_scalar(CAST(item AS VARCHAR), '$.value') AS value
FROM
parsed_data,
UNNEST(
CAST(json_extract(address_items, '$.items') AS ARRAY(JSON))
) AS t(item)
)

, bytes32_items_parsed AS (
SELECT
tx_hash,
index,
json_extract_scalar(CAST(item AS VARCHAR), '$.key') AS key_name,
json_extract_scalar(CAST(item AS VARCHAR), '$.value') AS value
FROM
parsed_data,
UNNEST(
CAST(json_extract(bytes32_items, '$.items') AS ARRAY(JSON))
) AS t(item)
)

, bytes_items_parsed AS (
SELECT
tx_hash,
index,
json_extract_scalar(CAST(item AS VARCHAR), '$.key') AS key_name,
json_extract_scalar(CAST(item AS VARCHAR), '$.value') AS value
FROM
parsed_data,
UNNEST(
CAST(json_extract(bytes_items, '$.items') AS ARRAY(JSON))
) AS t(item)
)

, string_items_parsed AS (
SELECT
tx_hash,
index,
json_extract_scalar(CAST(item AS VARCHAR), '$.key') AS key_name,
json_extract_scalar(CAST(item AS VARCHAR), '$.value') AS value
FROM
parsed_data,
UNNEST(
CAST(json_extract(string_items, '$.items') AS ARRAY(JSON))
) AS t(item)
)

, combined AS (
SELECT *
FROM address_items_parsed
UNION ALL
SELECT *
FROM bytes32_items_parsed
UNION ALL
SELECT *
FROM bytes_items_parsed
UNION ALL
SELECT *
FROM string_items_parsed
)

, evt_data_parsed AS (
SELECT
tx_hash,
index,

MAX(CASE WHEN key_name = 'account' THEN value END) AS account,
MAX(CASE WHEN key_name = 'key' THEN value END) AS "key",
MAX(CASE WHEN key_name = 'reasonBytes' THEN value END) AS reason_bytes,
MAX(CASE WHEN key_name = 'reason' THEN value END) AS reason

FROM
combined
GROUP BY tx_hash, index
)

, full_data AS (
SELECT
blockchain,
block_time,
DATE(block_time) AS block_date,
block_number,
ED.tx_hash,
ED.index,
contract_address,
event_name,
msg_sender,

from_hex(account) AS account,
from_hex("key") AS "key",
from_hex(reason_bytes) AS reason_bytes,
reason

FROM evt_data AS ED
LEFT JOIN evt_data_parsed AS EDP
ON ED.tx_hash = EDP.tx_hash
AND ED.index = EDP.index
)

--can be removed once decoded tables are fully denormalized
{{
add_tx_columns(
model_cte = 'full_data'
, blockchain = blockchain_name
, columns = ['from', 'to']
)
}}


Loading
Loading