From 040b3fdf9a0b8c91dc09e2a9ba1e699cf4a4b2f4 Mon Sep 17 00:00:00 2001 From: Austin <93135983+austinFlipside@users.noreply.github.com> Date: Tue, 27 Jun 2023 11:55:30 -0700 Subject: [PATCH] Stream 318/an 3432/stream 324/evm highl level abstractions (#24) * - create place holder configs for high level evm abstractions * - rename udf_config * - fixed macro bug * - add generic rpc_call * - add generic evm rpc udf * - add generic evm rpc udf * - more DRY primitives * WIP * - add example udft * - readme.MD * - updated comments on evm primitives * - add model to store signatures for UI * evm abstractions * use schema * Squashed commit of the following: commit df57d3309394d13407d5f4f7a1c27ab4e51ccb4e Author: Julius Remigio <14811322+juls858@users.noreply.github.com> Date: Thu Jun 15 12:31:00 2023 -0700 - remove unneeded model * - refactor pimitives to use schema with network name * schema fix and polygon * - added udf_rpc to live schema - prefixed primitives with udf_ * use crosschain table * use sources for crosschain * support all chains * add network * updated comments * all chains * remove map * reorg * remove optimism from map * Update utils.sql Return null instead of empty json object * add error column * Revert "add error column" This reverts commit 49bc7239a43afaa9974abc2ab9408310c0757aa1. * Revert "Update utils.sql" This reverts commit 1edbeef5eebea6a5bffe3fc599afd2289864b359. * Update utils.sql Return null instead of empty json object * Revert "Update utils.sql" This reverts commit e4c29b093235cf9a36ca34e1000d1ad1c1a7beb6. --------- Co-authored-by: Julius Remigio <14811322+juls858@users.noreply.github.com> --- README.md | 24 +- ...st_create_or_drop_function_from_config.sql | 2 +- analysis/test_crud_udfs_in_schema.sql | 4 +- macros/create_udfs.sql | 49 +- .../{configs.yaml.sql => core.yaml.sql} | 17 +- macros/livequery/evm.yaml.sql | 365 +++++ macros/livequery/evm_abstractions.sql | 1418 +++++++++++++++++ macros/livequery/evm_primitives.yaml.sql | 77 +- macros/livequery/utils.sql | 6 +- models/_internal__abi_map.sql | 22 + models/_internal__contracts_map.sql | 19 + models/sources.yml | 4 +- 12 files changed, 1937 insertions(+), 70 deletions(-) rename macros/livequery/{configs.yaml.sql => core.yaml.sql} (94%) create mode 100644 macros/livequery/evm.yaml.sql create mode 100644 macros/livequery/evm_abstractions.sql create mode 100644 models/_internal__abi_map.sql create mode 100644 models/_internal__contracts_map.sql diff --git a/README.md b/README.md index 655ba9b..4e64cd9 100644 --- a/README.md +++ b/README.md @@ -51,7 +51,7 @@ # Live Functions ## Limits and Best Practices -- The `udf_api` function is very powerful, but it is also very easy to abuse. Please be mindful of the following limits and best practices when using this function. +- The `udf_api` function is very powerful, but it is also very easy to abuse. Please be mindful of the following limits and best practices when using this function. - We reserve the right to disable the `udf_api` function for particular users, or as a whole, if we see it being abused. - Most APIs have rate limits. Please be mindful of these limits and do not abuse them. - Most of the limits you will encounter using this function will be on the API side. Please be sure to thoroughly read an API's documentation before using it. @@ -60,12 +60,12 @@ - API request (per row) response size limit: 6MB - API request timeout (per row) limit: 30 seconds - Data app query timeout limit: 15 minutes -- Batching is supported for JSON RPC requests. +- Batching is supported for JSON RPC requests. - Again, this is very easy to abuse. Be mindful of the API's rate limits when using this functionality. - It is strongly recommended that you start small and test your queries before requesting large amounts of data. -- Response data is not cached. +- Response data is not cached. - This means that if you run the same query twice, that API will be called twice. A future enhancement may address this need, but for now, please be mindful of this limitation. -- Many APIs require authentication. +- Many APIs require authentication. - Please see the [secret registration section](#registering-secrets) below for more information on how to register secrets for use with the `udf_api` function. - Technically, you can pass secrets into the `udf_api` function directly, but this is not recommended. - If you do pass your secrets without following the steps in the [secret registration section](#registering-secrets), your secrets will be visible in Flipside's internal query history. @@ -100,7 +100,7 @@ livequery.live.udf_api( ### Approved APIs - + | API Name | API Docs | Authentication Required | | --------------------- | -------------------------------------------------------------------------------------- | ----------------------- | | QuickNode | [Docs](https://www.quicknode.com/docs) | Yes | @@ -220,7 +220,7 @@ SELECT } ) as response ) -select +select value:id::string as address, value:name::string as name, value:totalLiquidity::int as totalLiquidity @@ -265,7 +265,7 @@ FROM ```sql -- you can use this function to retrieve data from IPFS. You can find the hash in the URL within several places onchain, including evm logs and traces. - SELECT + SELECT livequery.live.udf_api('https://ipfs.io/ipfs/QmTFX3TopS8JsgpfBLKGDnTiaWrRcfStDWDQaREzD36sWW') AS response; ``` @@ -276,7 +276,7 @@ FROM Utility functions are designed to make your life easier when interacting with blockchain data. ## udf_hex_to_int -This function converts a hex string to an integer. +This function converts a hex string to an integer. ### Syntax ```sql @@ -317,7 +317,7 @@ livequery.utils.udf_hex_to_int( --- -## udf_hex_to_string +## udf_hex_to_string This function converts a hex string to a string of human readable characters. It will handle obscure characters like emojis and special characters. @@ -336,7 +336,7 @@ livequery.utils.udf_hex_to_string( Convert Hex to Text ```sql - select + select livequery.utils.udf_hex_to_string('466C69707369646520726F636B73') as text1 ``` @@ -411,7 +411,7 @@ To register a secret, follow these steps: 1. Visit [Ephit](https://science.flipsidecrypto.xyz/ephit) to obtain an Ephemeral query that will securely link your API Endpoint to Flipside's backend. This will allow you to refer to the URL securely in our application without referencing it or exposing keys directly. 2. Fill out the form and click ***Submit this Credential*** 3. Paste the provided query into [Flipside](https://flipside.new) and query your node directly in the app with your submitted Credential (`{my_key}`) - + Registering a secret from Quicknode to query nodes directly in Flipside: 1. Sign up for a free [Quicknode API Account](https://www.quicknode.com/core-api) @@ -469,7 +469,7 @@ When False, none of the on-run-start macros are executed on model run Default values are False * Usage: -dbt run --var '{"UPDATE_UDFS_AND_SPS":True}' -m ... +`dbt run --var '{"UPDATE_UDFS_AND_SPS":True}' -m ...` Dropping and creating udfs can also be done without running a model: diff --git a/analysis/test_create_or_drop_function_from_config.sql b/analysis/test_create_or_drop_function_from_config.sql index 639f3b5..af28e28 100644 --- a/analysis/test_create_or_drop_function_from_config.sql +++ b/analysis/test_create_or_drop_function_from_config.sql @@ -1,4 +1,4 @@ -{%- set udfs = fromyaml(udf_configs()) -%} +{%- set udfs = fromyaml(config_core_udfs()) -%} {%- for udf in udfs -%} {{- create_or_drop_function_from_config(udf, drop_=True) -}} {{- create_or_drop_function_from_config(udf, drop_=False) -}} diff --git a/analysis/test_crud_udfs_in_schema.sql b/analysis/test_crud_udfs_in_schema.sql index 69b0c23..c8f4cbe 100644 --- a/analysis/test_crud_udfs_in_schema.sql +++ b/analysis/test_crud_udfs_in_schema.sql @@ -1 +1,3 @@ -{{- crud_udfs_in_schema(config_evm_rpc_primitives, "ethereum", None, drop_) -}} \ No newline at end of file +{{crud_udfs_in_schema(config_evm_high_level_abstractions, 'ethereum', 'mainnet', false)}} +{# {{- crud_udfs_in_schema(config_evm_rpc_primitives, "ethereum", None, False) -}} +{{- crud_udfs_in_schema(config_evm_rpc_primitives, "ethereum", None, true) -}} #} \ No newline at end of file diff --git a/macros/create_udfs.sql b/macros/create_udfs.sql index 418e790..f0d811e 100644 --- a/macros/create_udfs.sql +++ b/macros/create_udfs.sql @@ -7,12 +7,57 @@ CREATE SCHEMA IF NOT EXISTS _utils; CREATE SCHEMA IF NOT EXISTS _live; CREATE SCHEMA IF NOT EXISTS live; - {%- set udfs = fromyaml(udf_configs()) -%} + {%- set udfs = fromyaml(config_core_udfs()) -%} {%- for udf in udfs -%} {{- create_or_drop_function_from_config(udf, drop_=drop_) -}} {% endfor %} - {{- crud_udfs_in_schema(config_evm_rpc_primitives, "ethereum", None, drop_) -}} + {{- crud_udfs_in_schema(config_evm_rpc_primitives, "arbitrum_nova", "mainnet", drop_) -}} + {{- crud_udfs_in_schema(config_evm_rpc_primitives, "arbitrum_one", "goerli", drop_) -}} + {{- crud_udfs_in_schema(config_evm_rpc_primitives, "arbitrum_one", "mainnet", drop_) -}} + {{- crud_udfs_in_schema(config_evm_rpc_primitives, "avalanche_c", "mainnet", drop_) -}} + {{- crud_udfs_in_schema(config_evm_rpc_primitives, "avalanche_c", "testnet", drop_) -}} + {{- crud_udfs_in_schema(config_evm_rpc_primitives, "base", "goerli", drop_) -}} + {{- crud_udfs_in_schema(config_evm_rpc_primitives, "bsc", "mainnet", drop_) -}} + {{- crud_udfs_in_schema(config_evm_rpc_primitives, "bsc", "testnet", drop_) -}} + {{- crud_udfs_in_schema(config_evm_rpc_primitives, "celo", "mainnet", drop_) -}} + {{- crud_udfs_in_schema(config_evm_rpc_primitives, "ethereum", "goerli", drop_) -}} + {{- crud_udfs_in_schema(config_evm_rpc_primitives, "ethereum", "mainnet", drop_) -}} + {{- crud_udfs_in_schema(config_evm_rpc_primitives, "ethereum", "sepolia", drop_) -}} + {{- crud_udfs_in_schema(config_evm_rpc_primitives, "fantom", "mainnet", drop_) -}} + {{- crud_udfs_in_schema(config_evm_rpc_primitives, "gnosis", "mainnet", drop_) -}} + {{- crud_udfs_in_schema(config_evm_rpc_primitives, "harmony", "mainnet", drop_) -}} + {{- crud_udfs_in_schema(config_evm_rpc_primitives, "harmony", "testnet", drop_) -}} + {{- crud_udfs_in_schema(config_evm_rpc_primitives, "optimism", "goerli", drop_) -}} + {{- crud_udfs_in_schema(config_evm_rpc_primitives, "optimism", "mainnet", drop_) -}} + {{- crud_udfs_in_schema(config_evm_rpc_primitives, "polygon", "mainnet", drop_) -}} + {{- crud_udfs_in_schema(config_evm_rpc_primitives, "polygon", "testnet", drop_) -}} + {{- crud_udfs_in_schema(config_evm_rpc_primitives, "polygon_zkevm", "mainnet", drop_) -}} + {{- crud_udfs_in_schema(config_evm_rpc_primitives, "polygon_zkevm", "testnet", drop_) -}} + + {{- crud_udfs_in_schema(config_evm_high_level_abstractions, "arbitrum_nova", "mainnet", drop_) -}} + {{- crud_udfs_in_schema(config_evm_high_level_abstractions, "arbitrum_one", "goerli", drop_) -}} + {{- crud_udfs_in_schema(config_evm_high_level_abstractions, "arbitrum_one", "mainnet", drop_) -}} + {{- crud_udfs_in_schema(config_evm_high_level_abstractions, "avalanche_c", "mainnet", drop_) -}} + {{- crud_udfs_in_schema(config_evm_high_level_abstractions, "avalanche_c", "testnet", drop_) -}} + {{- crud_udfs_in_schema(config_evm_high_level_abstractions, "base", "goerli", drop_) -}} + {{- crud_udfs_in_schema(config_evm_high_level_abstractions, "bsc", "mainnet", drop_) -}} + {{- crud_udfs_in_schema(config_evm_high_level_abstractions, "bsc", "testnet", drop_) -}} + {{- crud_udfs_in_schema(config_evm_high_level_abstractions, "celo", "mainnet", drop_) -}} + {{- crud_udfs_in_schema(config_evm_high_level_abstractions, "ethereum", "goerli", drop_) -}} + {{- crud_udfs_in_schema(config_evm_high_level_abstractions, "ethereum", "mainnet", drop_) -}} + {{- crud_udfs_in_schema(config_evm_high_level_abstractions, "ethereum", "sepolia", drop_) -}} + {{- crud_udfs_in_schema(config_evm_high_level_abstractions, "fantom", "mainnet", drop_) -}} + {{- crud_udfs_in_schema(config_evm_high_level_abstractions, "gnosis", "mainnet", drop_) -}} + {{- crud_udfs_in_schema(config_evm_high_level_abstractions, "harmony", "mainnet", drop_) -}} + {{- crud_udfs_in_schema(config_evm_high_level_abstractions, "harmony", "testnet", drop_) -}} + {{- crud_udfs_in_schema(config_evm_high_level_abstractions, "optimism", "goerli", drop_) -}} + {{- crud_udfs_in_schema(config_evm_high_level_abstractions, "optimism", "mainnet", drop_) -}} + {{- crud_udfs_in_schema(config_evm_high_level_abstractions, "polygon", "mainnet", drop_) -}} + {{- crud_udfs_in_schema(config_evm_high_level_abstractions, "polygon", "testnet", drop_) -}} + {{- crud_udfs_in_schema(config_evm_high_level_abstractions, "polygon_zkevm", "mainnet", drop_) -}} + {{- crud_udfs_in_schema(config_evm_high_level_abstractions, "polygon_zkevm", "testnet", drop_) -}} + {% endset %} {% do run_query(sql) %} {% endif %} diff --git a/macros/livequery/configs.yaml.sql b/macros/livequery/core.yaml.sql similarity index 94% rename from macros/livequery/configs.yaml.sql rename to macros/livequery/core.yaml.sql index a24210d..9074f04 100644 --- a/macros/livequery/configs.yaml.sql +++ b/macros/livequery/core.yaml.sql @@ -1,4 +1,4 @@ -{% macro udf_configs() %} +{% macro config_core_udfs() %} {# UTILITY SCHEMA @@ -329,5 +329,20 @@ secret_name ) +- name: live.udf_rpc + signature: + - [blockchain, STRING] + - [network, STRING] + - [method, STRING] + - [parameters, VARIANT] + return_type: VARIANT + options: | + NOT NULL + RETURNS NULL ON NULL INPUT + VOLATILE + COMMENT = $$Executes an JSON RPC call on a blockchain.$$ + sql: | + {{ sql_live_rpc_call("method", "parameters", "blockchain", "network") | indent(4) -}} + {% endmacro %} diff --git a/macros/livequery/evm.yaml.sql b/macros/livequery/evm.yaml.sql new file mode 100644 index 0000000..df89a1c --- /dev/null +++ b/macros/livequery/evm.yaml.sql @@ -0,0 +1,365 @@ +{% macro config_evm_high_level_abstractions(blockchain, network) -%} +{# + This macro is used to generate the high level abstractions for an EVM + blockchain. + #} +{% set schema = blockchain ~ "_" ~ network %} +- name: {{ schema -}}.latest_native_balance + signature: + - [wallet, STRING, The address to get the balance of at the latest block] + return_type: + - "TABLE(blockchain STRING, network STRING, wallet_address STRING, symbol STRING, raw_balance STRING, balance FLOAT)" + - | + The table has the following columns: + * `blockchain` - The blockchain + * `network` - The network + * `wallet_address` - The wallet address + * `symbol` - The symbol of the native asset + * `raw_balance` - The unadjusted native asset balance + * `balance` - The adjusted native asset balance + options: | + NOT NULL + RETURNS NULL ON NULL INPUT + VOLATILE + COMMENT = $$Returns the native asset balance at the latest block for a given address.$$ + sql: | + {{ evm_latest_native_balance_string(schema, blockchain, network) | indent(4) -}} + +- name: {{ schema -}}.latest_native_balance + signature: + - [wallets, ARRAY, An array of addresses string to get the balance of at the latest block] + return_type: + - "TABLE(blockchain STRING, network STRING, wallet_address STRING, symbol STRING, raw_balance STRING, balance FLOAT)" + options: | + NOT NULL + RETURNS NULL ON NULL INPUT + VOLATILE + COMMENT = $$Returns the native asset balances at the latest block for given addresses.$$ + sql: | + {{ evm_latest_native_balance_array(schema, blockchain, network) | indent(4) -}} + +- name: {{ schema -}}.latest_token_balance + signature: + - [wallet, STRING, The address to get the balance of at the latest block] + - [token, STRING, The address of the token to get the balance of] + return_type: + - "TABLE(blockchain STRING, network STRING, wallet_address STRING, token_address STRING, symbol STRING, raw_balance STRING, balance FLOAT)" + options: | + NOT NULL + RETURNS NULL ON NULL INPUT + VOLATILE + COMMENT = $$Returns the token balance at the latest block for a given address and token address. Supports ERC20 and ERC721 tokens.$$ + sql: | + {{ evm_latest_token_balance_ss(schema, blockchain, network) | indent(4) -}} + +- name: {{ schema -}}.latest_token_balance + signature: + - [wallet, STRING, The address to get the balance of at the latest block] + - [tokens, ARRAY, An array of address strings of the tokens to get the balance of] + return_type: + - "TABLE(blockchain STRING, network STRING, wallet_address STRING, token_address STRING, symbol STRING, raw_balance STRING, balance FLOAT)" + options: | + NOT NULL + RETURNS NULL ON NULL INPUT + VOLATILE + COMMENT = $$Returns the token balances at the latest block for a given address and multiple token addresses. Supports ERC20 and ERC721 tokens.$$ + sql: | + {{ evm_latest_token_balance_sa(schema, blockchain, network) | indent(4) -}} + +- name: {{ schema -}}.latest_token_balance + signature: + - [wallets, ARRAY, An array of addresses string to get the balance of at the latest block] + - [token, STRING, The address of the token to get the balance of] + return_type: + - "TABLE(blockchain STRING, network STRING, wallet_address STRING, token_address STRING, symbol STRING, raw_balance STRING, balance FLOAT)" + options: | + NOT NULL + RETURNS NULL ON NULL INPUT + VOLATILE + COMMENT = $$Returns the token balances at the latest block for multiple addresses and a single token address. Supports ERC20 and ERC721 tokens.$$ + sql: | + {{ evm_latest_token_balance_as(schema, blockchain, network) | indent(4) -}} + +- name: {{ schema -}}.latest_token_balance + signature: + - [wallets, ARRAY, An array of addresses string to get the balance of at the latest block] + - [tokens, ARRAY, An array of address strings of the tokens to get the balance of] + return_type: + - "TABLE(blockchain STRING, network STRING, wallet_address STRING, token_address STRING, symbol STRING, raw_balance STRING, balance FLOAT)" + options: | + NOT NULL + RETURNS NULL ON NULL INPUT + VOLATILE + COMMENT = $$Returns the token balances at the latest block for multiple addresses and multiple token addresses. Supports ERC20 and ERC721 tokens.$$ + sql: | + {{ evm_latest_token_balance_aa(schema, blockchain, network) | indent(4) -}} + +- name: {{ schema -}}.historical_token_balance + signature: + - [wallet, STRING, The address to get the balance of at the input block] + - [token, STRING, The address of the token to get the balance of] + - [block_number, INTEGER, The block number to get the balance at] + return_type: + - "TABLE(blockchain STRING, network STRING, wallet_address STRING, token_address STRING, symbol STRING, block_number INTEGER, raw_balance STRING, balance FLOAT)" + options: | + NOT NULL + RETURNS NULL ON NULL INPUT + VOLATILE + COMMENT = $$Returns the token balance for a given address and token address at a specific block. Supports ERC20 and ERC721 tokens.$$ + sql: | + {{ evm_historical_token_balance_ssi(schema, blockchain, network) | indent(4) -}} + +- name: {{ schema -}}.historical_token_balance + signature: + - [wallet, STRING, The address to get the balance of at the input block] + - [token, STRING, The address of the token to get the balance of] + - [block_numbers, ARRAY, The block numbers to get the balance at] + return_type: + - "TABLE(blockchain STRING, network STRING, wallet_address STRING, token_address STRING, symbol STRING, block_number INTEGER, raw_balance STRING, balance FLOAT)" + options: | + NOT NULL + RETURNS NULL ON NULL INPUT + VOLATILE + COMMENT = $$Returns the token balances for a given address and token address at multiple specific blocks. Supports ERC20 and ERC721 tokens.$$ + sql: | + {{ evm_historical_token_balance_ssa(schema, blockchain, network) | indent(4) -}} + +- name: {{ schema -}}.historical_token_balance + signature: + - [wallets, ARRAY, The addresses to get the balance of at the input block] + - [token, STRING, The address of the token to get the balance of] + - [block_number, INTEGER, The block number to get the balance at] + return_type: + - "TABLE(blockchain STRING, network STRING, wallet_address STRING, token_address STRING, symbol STRING, block_number INTEGER, raw_balance STRING, balance FLOAT)" + options: | + NOT NULL + RETURNS NULL ON NULL INPUT + VOLATILE + COMMENT = $$Returns the token balances for multiple addresses and a given token addresses at a specific block. Supports ERC20 and ERC721 tokens.$$ + sql: | + {{ evm_historical_token_balance_asi(schema, blockchain, network) | indent(4) -}} + +- name: {{ schema -}}.historical_token_balance + signature: + - [wallet, STRING, The address to get the balance of at the input block] + - [tokens, ARRAY, An array of address strings of the tokens to get the balance of] + - [block_number, INTEGER, The block number to get the balance at] + return_type: + - "TABLE(blockchain STRING, network STRING, wallet_address STRING, token_address STRING, symbol STRING, block_number INTEGER, raw_balance STRING, balance FLOAT)" + options: | + NOT NULL + RETURNS NULL ON NULL INPUT + VOLATILE + COMMENT = $$Returns the token balances for a given address and multiple token addresses at a specific block. Supports ERC20 and ERC721 tokens.$$ + sql: | + {{ evm_historical_token_balance_sai(schema, blockchain, network) | indent(4) -}} + +- name: {{ schema -}}.historical_token_balance + signature: + - [wallet, STRING, The address to get the balance of at the input block] + - [tokens, ARRAY, An array of address strings of the tokens to get the balance of] + - [block_numbers, ARRAY, The block numbers to get the balance at] + return_type: + - "TABLE(blockchain STRING, network STRING, wallet_address STRING, token_address STRING, symbol STRING, block_number INTEGER, raw_balance STRING, balance FLOAT)" + options: | + NOT NULL + RETURNS NULL ON NULL INPUT + VOLATILE + COMMENT = $$Returns the token balances for a given address and multiple token addresses at multiple specific blocks. Supports ERC20 and ERC721 tokens.$$ + sql: | + {{ evm_historical_token_balance_saa(schema, blockchain, network) | indent(4) -}} + +- name: {{ schema -}}.historical_token_balance + signature: + - [wallets, ARRAY, An array of address strings to get the balance of at the input block] + - [tokens, ARRAY, An array of address strings of the tokens to get the balance of] + - [block_number, INTEGER, The block number to get the balance at] + return_type: + - "TABLE(blockchain STRING, network STRING, wallet_address STRING, token_address STRING, symbol STRING, block_number INTEGER, raw_balance STRING, balance FLOAT)" + options: | + NOT NULL + RETURNS NULL ON NULL INPUT + VOLATILE + COMMENT = $$Returns the token balances for multiple addresses and multiple token addresses at a specific block. Supports ERC20 and ERC721 tokens.$$ + sql: | + {{ evm_historical_token_balance_aai(schema, blockchain, network) | indent(4) -}} + +- name: {{ schema -}}.historical_token_balance + signature: + - [wallets, ARRAY, An array of address strings to get the balance of at the input block] + - [tokens, ARRAY, An array of address strings of the tokens to get the balance of] + - [block_numbers, ARRAY, The block numbers to get the balance at] + return_type: + - "TABLE(blockchain STRING, network STRING, wallet_address STRING, token_address STRING, symbol STRING, block_number INTEGER, raw_balance STRING, balance FLOAT)" + options: | + NOT NULL + RETURNS NULL ON NULL INPUT + VOLATILE + COMMENT = $$Returns the token balances for multiple addresses and multiple token addresses at multiple specific blocks. Supports ERC20 and ERC721 tokens.$$ + sql: | + {{ evm_historical_token_balance_aaa(schema, blockchain, network) | indent(4) -}} + +- name: {{ schema -}}.historical_native_balance + signature: + - [wallet, STRING, The address to get the balance of at the input block] + - [block_number, INTEGER, The block number to get the balance at] + return_type: + - "TABLE(blockchain STRING, network STRING, wallet_address STRING, symbol STRING, block_number INTEGER, raw_balance STRING, balance FLOAT)" + options: | + NOT NULL + RETURNS NULL ON NULL INPUT + VOLATILE + COMMENT = $$Returns the native asset balance for a given address at a specific block.$$ + sql: | + {{ evm_historical_native_balance_si(schema, blockchain, network) | indent(4) -}} + +- name: {{ schema -}}.historical_native_balance + signature: + - [wallet, STRING, The address to get the balance of at the input block] + - [block_numbers, ARRAY, The block numbers to get the balance at] + return_type: + - "TABLE(blockchain STRING, network STRING, wallet_address STRING, symbol STRING, block_number INTEGER, raw_balance STRING, balance FLOAT)" + options: | + NOT NULL + RETURNS NULL ON NULL INPUT + VOLATILE + COMMENT = $$Returns the native asset balances for a given address at multiple specific blocks.$$ + sql: | + {{ evm_historical_native_balance_sa(schema, blockchain, network) | indent(4) -}} + +- name: {{ schema -}}.historical_native_balance + signature: + - [wallets, ARRAY, An array of address strings to get the balance of at the input block] + - [block_number, INTEGER, The block number to get the balance at] + return_type: + - "TABLE(blockchain STRING, network STRING, wallet_address STRING, symbol STRING, block_number INTEGER, raw_balance STRING, balance FLOAT)" + options: | + NOT NULL + RETURNS NULL ON NULL INPUT + VOLATILE + COMMENT = $$Returns the native asset balances for multiple addresses at a specific block.$$ + sql: | + {{ evm_historical_native_balance_ai(schema, blockchain, network) | indent(4) -}} + +- name: {{ schema -}}.historical_native_balance + signature: + - [wallets, ARRAY, An array of address strings to get the balance of at the input block] + - [block_numbers, ARRAY, The block numbers to get the balance at] + return_type: + - "TABLE(blockchain STRING, network STRING, wallet_address STRING, symbol STRING, block_number INTEGER, raw_balance STRING, balance FLOAT)" + options: | + NOT NULL + RETURNS NULL ON NULL INPUT + VOLATILE + COMMENT = $$Returns the native asset balances for multiple addresses at multiple specific blocks.$$ + sql: | + {{ evm_historical_native_balance_aa(schema, blockchain, network) | indent(4) -}} + +- name: {{ schema -}}.latest_contract_events + signature: + - [address, STRING, The address of the contract to get the events of] + return_type: + - "TABLE(blockchain STRING, network STRING, tx_hash STRING, block_number INTEGER, event_index INTEGER, contract_address STRING, event_topics ARRAY, event_data STRING)" + options: | + NOT NULL + RETURNS NULL ON NULL INPUT + VOLATILE + COMMENT = $$Returns the latest events emitted by a contract in the last 100 blocks.$$ + sql: | + {{ evm_latest_contract_events_s(schema, blockchain, network) | indent(4) -}} + +- name: {{ schema -}}.latest_contract_events + signature: + - [address, STRING, The address of the contract to get the events of] + - [lookback, INTEGER, The number of blocks to look back. Please note there are RPC limitations on this method.] + return_type: + - "TABLE(blockchain STRING, network STRING, tx_hash STRING, block_number INTEGER, event_index INTEGER, contract_address STRING, event_topics ARRAY, event_data STRING)" + options: | + NOT NULL + RETURNS NULL ON NULL INPUT + VOLATILE + COMMENT = $$Returns the latest events emitted by a contract within the last `lookback` blocks. *Please note there are RPC limitations on this method.*$$ + sql: | + {{ evm_latest_contract_events_si(schema, blockchain, network) | indent(4) -}} + +- name: {{ schema -}}.latest_contract_events + signature: + - [addresses, ARRAY, The addresses of the contracts to get the events of] + return_type: + - "TABLE(blockchain STRING, network STRING, tx_hash STRING, block_number INTEGER, event_index INTEGER, contract_address STRING, event_topics ARRAY, event_data STRING)" + options: | + NOT NULL + RETURNS NULL ON NULL INPUT + VOLATILE + COMMENT = $$Returns the latest events emitted by multiple contracts in the last 100 blocks.$$ + sql: | + {{ evm_latest_contract_events_a(schema, blockchain, network) | indent(4) -}} + +- name: {{ schema -}}.latest_contract_events + signature: + - [addresses, ARRAY, The addresses of the contracts to get the events of] + - [lookback, INTEGER, The number of blocks to look back. Please note there are RPC limitations on this method.] + return_type: + - "TABLE(blockchain STRING, network STRING, tx_hash STRING, block_number INTEGER, event_index INTEGER, contract_address STRING, event_topics ARRAY, event_data STRING)" + options: | + NOT NULL + RETURNS NULL ON NULL INPUT + VOLATILE + COMMENT = $$Returns the latest events emitted by multiple contracts within the last `lookback` blocks. *Please note there are RPC limitations on this method.*$$ + sql: | + {{ evm_latest_contract_events_ai(schema, blockchain, network) | indent(4) -}} + +- name: {{ schema -}}.latest_contract_events_decoded + signature: + - [address, STRING, The address of the contract to get the decoded events of] + return_type: + - "TABLE(blockchain STRING, network STRING, tx_hash STRING, block_number INTEGER, event_index INTEGER, event_name STRING, contract_address STRING, event_topics ARRAY, event_data STRING, decoded_data OBJECT)" + options: | + NOT NULL + RETURNS NULL ON NULL INPUT + VOLATILE + COMMENT = $$RReturns the latest decoded events emitted by a contract in the last 100 blocks. Submit missing ABIs [here](https://science.flipsidecrypto.xyz/abi-requestor/).$$ + sql: | + {{ evm_latest_contract_events_decoded_s(schema, blockchain, network) | indent(4) -}} + +- name: {{ schema -}}.latest_contract_events_decoded + signature: + - [addresses, ARRAY, The addresses of the contracts to get the decoded events of] + return_type: + - "TABLE(blockchain STRING, network STRING, tx_hash STRING, block_number INTEGER, event_index INTEGER, event_name STRING, contract_address STRING, event_topics ARRAY, event_data STRING, decoded_data OBJECT)" + options: | + NOT NULL + RETURNS NULL ON NULL INPUT + VOLATILE + COMMENT = $$Returns the latest decoded events emitted by multiple contracts in the last 100 blocks. Submit missing ABIs [here](https://science.flipsidecrypto.xyz/abi-requestor/).$$ + sql: | + {{ evm_latest_contract_events_decoded_a(schema, blockchain, network) | indent(4) -}} + +- name: {{ schema -}}.latest_contract_events_decoded + signature: + - [address, STRING, The address of the contract to get the decoded events of] + - [lookback, INTEGER, The number of blocks to look back. Please note there are RPC limitations on this method.] + return_type: + - "TABLE(blockchain STRING, network STRING, tx_hash STRING, block_number INTEGER, event_index INTEGER, event_name STRING, contract_address STRING, event_topics ARRAY, event_data STRING, decoded_data OBJECT)" + options: | + NOT NULL + RETURNS NULL ON NULL INPUT + VOLATILE + COMMENT = $$Returns the latest decoded events emitted by a contract within the last `lookback` blocks. Submit missing ABIs [here](https://science.flipsidecrypto.xyz/abi-requestor/). *Please note there are RPC limitations on this method.*$$ + sql: | + {{ evm_latest_contract_events_decoded_si(schema, blockchain, network) | indent(4) -}} + +- name: {{ schema -}}.latest_contract_events_decoded + signature: + - [addresses, ARRAY, The addresses of the contracts to get the decoded events of] + - [lookback, INTEGER, The number of blocks to look back. Please note there are RPC limitations on this method.] + return_type: + - "TABLE(blockchain STRING, network STRING, tx_hash STRING, block_number INTEGER, event_index INTEGER, event_name STRING, contract_address STRING, event_topics ARRAY, event_data STRING, decoded_data OBJECT)" + options: | + NOT NULL + RETURNS NULL ON NULL INPUT + VOLATILE + COMMENT = $$Returns the latest decoded events emitted by multiple contracts within the last `lookback` blocks. Submit missing ABIs [here](https://science.flipsidecrypto.xyz/abi-requestor/). *Please note there are RPC limitations on this method.* $$ + sql: | + {{ evm_latest_contract_events_decoded_ai(schema, blockchain, network) | indent(4) -}} +{%- endmacro -%} \ No newline at end of file diff --git a/macros/livequery/evm_abstractions.sql b/macros/livequery/evm_abstractions.sql new file mode 100644 index 0000000..af132ab --- /dev/null +++ b/macros/livequery/evm_abstractions.sql @@ -0,0 +1,1418 @@ +{% macro evm_latest_native_balance_string(schema, blockchain, network) %} +SELECT + '{{blockchain}}' AS blockchain, + '{{network}}' AS network, + lower(wallet) AS wallet_address, + CASE + WHEN '{{blockchain}}' ILIKE 'avalanche%' THEN 'AVAX' + WHEN '{{blockchain}}' ILIKE 'polygon%' THEN 'MATIC' + WHEN '{{blockchain}}' ILIKE 'binance%' THEN 'BNB' + WHEN '{{blockchain}}' ILIKE 'gnosis%' THEN 'xDAI' + WHEN '{{blockchain}}' ILIKE 'ethereum%' THEN 'ETH' + WHEN '{{blockchain}}' ILIKE 'arbitrum%' THEN 'ETH' + WHEN '{{blockchain}}' ILIKE 'optimism%' THEN 'ETH' + WHEN '{{blockchain}}' ILIKE 'base%' THEN 'ETH' + WHEN '{{blockchain}}' ILIKE 'fantom%' THEN 'ETH' + WHEN '{{blockchain}}' ILIKE 'harmony%' THEN 'ONE' + END AS symbol, + utils.udf_hex_to_int({{schema}}.udf_rpc_eth_get_balance(wallet_address,'latest')::string) AS raw_balance, + (raw_balance / POW(10,18))::float AS balance +{% endmacro %} + +{% macro evm_latest_native_balance_array(schema, blockchain, network) %} +WITH address_inputs AS ( + SELECT wallets AS wallet_array +), +flat_addresses AS ( + SELECT lower(value::string) AS wallet_address + FROM address_inputs a, + LATERAL FLATTEN(input => a.wallet_array) +), +node_call AS ( + SELECT wallet_address, + {{schema}}.udf_rpc_eth_get_balance(wallet_address,'latest')::string AS hex_balance + FROM flat_addresses +) +SELECT + '{{blockchain}}' AS blockchain, + '{{network}}' AS network, + wallet_address, + CASE + WHEN '{{blockchain}}' ILIKE 'avalanche%' THEN 'AVAX' + WHEN '{{blockchain}}' ILIKE 'polygon%' THEN 'MATIC' + WHEN '{{blockchain}}' ILIKE 'binance%' THEN 'BNB' + WHEN '{{blockchain}}' ILIKE 'gnosis%' THEN 'xDAI' + WHEN '{{blockchain}}' ILIKE 'ethereum%' THEN 'ETH' + WHEN '{{blockchain}}' ILIKE 'arbitrum%' THEN 'ETH' + WHEN '{{blockchain}}' ILIKE 'optimism%' THEN 'ETH' + WHEN '{{blockchain}}' ILIKE 'base%' THEN 'ETH' + WHEN '{{blockchain}}' ILIKE 'fantom%' THEN 'ETH' + WHEN '{{blockchain}}' ILIKE 'harmony%' THEN 'ONE' + END AS symbol, + utils.udf_hex_to_int(hex_balance) AS raw_balance, + (raw_balance / POW(10,18))::FLOAT AS balance +FROM node_call +{% endmacro %} + +{% macro evm_latest_token_balance_ss(schema, blockchain, network) %} +WITH inputs AS ( + SELECT + lower(token) AS token_address, + lower(wallet) AS wallet_address, + '0x70a08231' AS function_sig, + CONCAT( + function_sig, + LPAD(REPLACE(wallet_address, '0x', ''), 64, 0) + ) AS DATA +), +node_call AS ( + SELECT + wallet_address, + token_address, + symbol, + {{schema}}.udf_rpc_eth_call(object_construct_keep_null('from', null, 'to', token_address, 'data', data),'latest')::string AS eth_call, + utils.udf_hex_to_int(eth_call::string) AS raw_balance, + raw_balance::INT / POW(10, ifnull(decimals,0)) AS balance + FROM + inputs + LEFT JOIN {{ ref('_internal__contracts_map') }} + ON token_address = address + and blockchain = '{{blockchain}}' +) +SELECT + '{{blockchain}}' AS blockchain, + '{{network}}' AS network, + wallet_address, + token_address, + symbol, + raw_balance, + balance +FROM node_call +{% endmacro %} + +{% macro evm_latest_token_balance_sa(schema, blockchain, network) %} +WITH inputs AS ( + SELECT tokens, wallet +), +flat_rows AS ( + SELECT + lower(value::string) AS token_address, + lower(wallet::string) AS wallet_address, + '0x70a08231' AS function_sig, + CONCAT( + function_sig, + LPAD(REPLACE(wallet_address, '0x', ''), 64, 0) + ) AS DATA + FROM inputs, + LATERAL FLATTEN(input => tokens) +), +final AS ( + SELECT + wallet_address, + token_address, + symbol, + {{schema}}.udf_rpc_eth_call(object_construct_keep_null('from', null, 'to', token_address, 'data', data),'latest')::string AS eth_call, + utils.udf_hex_to_int(eth_call::string) AS raw_balance, + raw_balance::INT / POW(10, ifnull(decimals,0)) AS balance + FROM + flat_rows + LEFT JOIN {{ ref('_internal__contracts_map') }} + ON token_address = address + and blockchain = '{{blockchain}}' +) +SELECT + '{{blockchain}}' AS blockchain, + '{{network}}' AS network, + wallet_address, + token_address, + symbol, + raw_balance, + balance +FROM final +{% endmacro %} + +{% macro evm_latest_token_balance_as(schema, blockchain, network) %} +WITH inputs AS ( + SELECT token, wallets +), +flat_rows AS ( + SELECT + lower(value::string) AS wallet_address, + lower(token::string) AS token_address, + '0x70a08231' AS function_sig, + CONCAT( + function_sig, + LPAD(REPLACE(wallet_address, '0x', ''), 64, 0) + ) AS DATA + FROM inputs, + LATERAL FLATTEN(input => wallets) +), +final AS ( + SELECT + wallet_address, + token_address, + symbol, + {{schema}}.udf_rpc_eth_call(object_construct_keep_null('from', null, 'to', token_address, 'data', data),'latest')::string AS eth_call, + utils.udf_hex_to_int(eth_call::string) AS raw_balance, + raw_balance::INT / POW(10, ifnull(decimals,0)) AS balance + FROM + flat_rows + LEFT JOIN {{ ref('_internal__contracts_map') }} + ON token_address = address + and blockchain = '{{blockchain}}' +) +SELECT + '{{blockchain}}' AS blockchain, + '{{network}}' AS network, + wallet_address, + token_address, + symbol, + raw_balance, + balance +FROM final +{% endmacro %} + +{% macro evm_latest_token_balance_aa(schema, blockchain, network) %} +WITH inputs AS ( + SELECT tokens, wallets +), +flat_rows AS ( + SELECT + lower(tokens.VALUE::STRING) AS token_address, + lower(wallets.VALUE::STRING) AS wallet_address, + '0x70a08231' AS function_sig, + CONCAT( + function_sig, + LPAD(REPLACE(wallet_address, '0x', ''), 64, 0) + ) AS DATA + FROM + inputs, + LATERAL FLATTEN(input => tokens) tokens, + LATERAL FLATTEN(input => wallets) wallets +), +final AS ( + SELECT + wallet_address, + token_address, + symbol, + {{schema}}.udf_rpc_eth_call(object_construct_keep_null('from', null, 'to', token_address, 'data', data),'latest')::string AS eth_call, + utils.udf_hex_to_int(eth_call::string) AS raw_balance, + raw_balance::INT / POW(10, ifnull(decimals,0)) AS balance + FROM + flat_rows + LEFT JOIN {{ ref('_internal__contracts_map') }} + ON token_address = address + and blockchain = '{{blockchain}}' +) +SELECT + '{{blockchain}}' AS blockchain, + '{{network}}' AS network, + wallet_address, + token_address, + symbol, + raw_balance, + balance +FROM final +{% endmacro %} + +{% macro evm_historical_token_balance_ssi(schema, blockchain, network) %} +WITH inputs AS ( + SELECT + LOWER(token) AS token_address, + LOWER(wallet) AS wallet_address, + '0x70a08231' AS function_sig, + CONCAT( + function_sig, + LPAD(REPLACE(wallet_address, '0x', ''), 64, 0) + ) AS data, + block_number +), final AS ( + SELECT + wallet_address, + token_address, + symbol, + block_number, + {{schema}}.udf_rpc_eth_call(OBJECT_CONSTRUCT_KEEP_NULL('from', NULL, 'to', token_address, 'data', data), CONCAT('0x', TRIM(TO_CHAR(block_number, 'XXXXXXXXXX'))))::STRING AS eth_call, + utils.udf_hex_to_int(eth_call::STRING) AS raw_balance, + raw_balance::INT / POW(10, ifnull(decimals,0)) AS balance + FROM + inputs + LEFT JOIN {{ ref('_internal__contracts_map') }} + ON token_address = address + AND blockchain = '{{blockchain}}' +) +SELECT + '{{blockchain}}' AS blockchain, + '{{network}}' AS network, + wallet_address, + token_address, + symbol, + block_number, + raw_balance, + balance +FROM final +{% endmacro %} + +{% macro evm_historical_token_balance_ssa(schema, blockchain, network) %} +WITH block_inputs AS ( + SELECT block_numbers +), +blocks AS ( + SELECT value::INTEGER AS block_number + FROM block_inputs, + LATERAL FLATTEN(input => block_numbers) +), +inputs AS ( + SELECT + LOWER(token) AS token_address, + LOWER(wallet) AS wallet_address, + '0x70a08231' AS function_sig, + CONCAT( + function_sig, + LPAD(REPLACE(wallet_address, '0x', ''), 64, 0) + ) AS data +), +final AS ( + SELECT + wallet_address, + token_address, + symbol, + blocks.block_number, + {{schema}}.udf_rpc_eth_call(OBJECT_CONSTRUCT_KEEP_NULL('from', NULL, 'to', token_address, 'data', data), CONCAT('0x', TRIM(TO_CHAR(blocks.block_number, 'XXXXXXXXXX'))))::STRING AS eth_call, + utils.udf_hex_to_int(eth_call::STRING) AS raw_balance, + raw_balance::INT / POW(10, ifnull(decimals,0)) AS balance + FROM + inputs + CROSS JOIN blocks + LEFT JOIN {{ ref('_internal__contracts_map') }} + ON token_address = address + AND blockchain = '{{blockchain}}' +) +SELECT + '{{blockchain}}' AS blockchain, + '{{network}}' AS network, + wallet_address, + token_address, + symbol, + block_number, + raw_balance, + balance +FROM final +{% endmacro %} + +{% macro evm_historical_token_balance_asi(schema, blockchain, network) %} +WITH wallet_inputs AS ( + SELECT wallets +), +wallets AS ( + SELECT lower(value::STRING) AS wallet + FROM wallet_inputs, + LATERAL FLATTEN(input => wallets) +), +inputs AS ( + SELECT + LOWER(token) AS token_address, + wallet, + '0x70a08231' AS function_sig, + CONCAT( + function_sig, + LPAD(REPLACE(wallet, '0x', ''), 64, 0) + ) AS data + FROM wallets +), +final AS ( + SELECT + wallet AS wallet_address, + token_address, + symbol, + block_number, + {{schema}}.udf_rpc_eth_call(OBJECT_CONSTRUCT_KEEP_NULL('from', NULL, 'to', token_address, 'data', data), CONCAT('0x', TRIM(TO_CHAR(block_number, 'XXXXXXXXXX'))))::STRING AS eth_call, + utils.udf_hex_to_int(eth_call::STRING) AS raw_balance, + raw_balance::INT / POW(10, ifnull(decimals,0)) AS balance + FROM + inputs + LEFT JOIN {{ ref('_internal__contracts_map') }} + ON token_address = address + AND blockchain = '{{blockchain}}' +) +SELECT + '{{blockchain}}' AS blockchain, + '{{network}}' AS network, + wallet_address, + token_address, + symbol, + block_number, + raw_balance, + balance +FROM final +{% endmacro %} + +{% macro evm_historical_token_balance_asa(schema, blockchain, network) %} +WITH block_inputs AS ( + SELECT block_numbers +), +blocks AS ( + SELECT value::INTEGER AS block_number + FROM block_inputs, + LATERAL FLATTEN(input => block_numbers) +), +wallet_inputs AS ( + SELECT wallets +), +wallets AS ( + SELECT lower(value::STRING) AS wallet + FROM wallet_inputs, + LATERAL FLATTEN(input => wallets) +), +inputs AS ( + SELECT + LOWER(token) AS token_address, + wallet, + '0x70a08231' AS function_sig, + CONCAT( + function_sig, + LPAD(REPLACE(wallet, '0x', ''), 64, '0') + ) AS data + FROM wallets +), +final AS ( + SELECT + wallet AS wallet_address, + token_address, + symbol, + blocks.block_number, + {{schema}}.udf_rpc_eth_call(OBJECT_CONSTRUCT_KEEP_NULL('from', NULL, 'to', token_address, 'data', data), CONCAT('0x', TRIM(TO_CHAR(blocks.block_number, 'XXXXXXXXXX'))))::STRING AS eth_call, + utils.udf_hex_to_int(eth_call::STRING) AS raw_balance, + raw_balance::INT / POW(10, ifnull(decimals,0)) AS balance + FROM + inputs + CROSS JOIN blocks + LEFT JOIN {{ ref('_internal__contracts_map') }} + ON token_address = address + AND blockchain = '{{blockchain}}' +) +SELECT + '{{blockchain}}' AS blockchain, + '{{network}}' AS network, + wallet_address, + token_address, + symbol, + block_number, + raw_balance, + balance +FROM final +{% endmacro %} + +{% macro evm_historical_token_balance_sai(schema, blockchain, network) %} +WITH token_inputs AS ( + SELECT tokens +), +tokens AS ( + SELECT value::STRING AS token + FROM token_inputs, + LATERAL FLATTEN(input => tokens) +), +inputs AS ( + SELECT + LOWER(token) AS token_address, + LOWER(wallet) AS wallet_address, + '0x70a08231' AS function_sig, + CONCAT( + function_sig, + LPAD(REPLACE(wallet_address, '0x', ''), 64, '0') + ) AS data + FROM + tokens +), +final AS ( + SELECT + wallet_address, + token_address, + symbol, + block_number, + {{schema}}.udf_rpc_eth_call(OBJECT_CONSTRUCT_KEEP_NULL('from', NULL, 'to', token_address, 'data', data), CONCAT('0x', TRIM(TO_CHAR(block_number, 'XXXXXXXXXX'))))::STRING AS eth_call, + utils.udf_hex_to_int(eth_call::STRING) AS raw_balance, + raw_balance::INT / POW(10, ifnull(decimals,0)) AS balance + FROM + inputs + LEFT JOIN {{ ref('_internal__contracts_map') }} + ON token_address = address + AND blockchain = '{{blockchain}}' +) +SELECT + '{{blockchain}}' AS blockchain, + '{{network}}' AS network, + wallet_address, + token_address, + symbol, + block_number, + raw_balance, + balance +FROM final +{% endmacro %} + +{% macro evm_historical_token_balance_saa(schema, blockchain, network) %} +WITH block_inputs AS ( + SELECT block_numbers +), +blocks AS ( + SELECT value::INTEGER AS block_number + FROM block_inputs, + LATERAL FLATTEN(input => block_numbers) +), +token_inputs AS ( + SELECT tokens +), +tokens AS ( + SELECT value::STRING AS token + FROM token_inputs, + LATERAL FLATTEN(input => tokens) +), +inputs AS ( + SELECT + LOWER(token) AS token_address, + LOWER(wallet) AS wallet_address, + '0x70a08231' AS function_sig, + CONCAT( + function_sig, + LPAD(REPLACE(wallet_address, '0x', ''), 64, '0') + ) AS data + FROM + tokens +), +final AS ( + SELECT + wallet_address, + token_address, + symbol, + blocks.block_number, + {{schema}}.udf_rpc_eth_call(OBJECT_CONSTRUCT_KEEP_NULL('from', NULL, 'to', token_address, 'data', data), CONCAT('0x', TRIM(TO_CHAR(blocks.block_number, 'XXXXXXXXXX'))))::STRING AS eth_call, + utils.udf_hex_to_int(eth_call::STRING) AS raw_balance, + raw_balance::INT / POW(10, ifnull(decimals,0)) AS balance + FROM + inputs + CROSS JOIN blocks + LEFT JOIN {{ ref('_internal__contracts_map') }} + ON token_address = address + AND blockchain = '{{blockchain}}' +) +SELECT + '{{blockchain}}' AS blockchain, + '{{network}}' AS network, + wallet_address, + token_address, + symbol, + block_number, + raw_balance, + balance +FROM final +{% endmacro %} + +{% macro evm_historical_token_balance_aai(schema, blockchain, network) %} +WITH token_inputs AS ( + SELECT tokens +), +tokens AS ( + SELECT value::STRING AS token + FROM token_inputs, + LATERAL FLATTEN(input => tokens) +), +wallet_inputs AS ( + SELECT wallets +), +wallets AS ( + SELECT lower(value::STRING) AS wallet + FROM wallet_inputs, + LATERAL FLATTEN(input => wallets) +), +inputs AS ( + SELECT + LOWER(token) AS token_address, + wallet AS wallet_address, + '0x70a08231' AS function_sig, + CONCAT( + function_sig, + LPAD(REPLACE(wallet_address, '0x', ''), 64, '0') + ) AS data + FROM + tokens, + wallets +), +final AS ( + SELECT + wallet_address, + token_address, + symbol, + block_number, + {{schema}}.udf_rpc_eth_call(OBJECT_CONSTRUCT_KEEP_NULL('from', NULL, 'to', token_address, 'data', data), CONCAT('0x', TRIM(TO_CHAR(block_number, 'XXXXXXXXXX'))))::STRING AS eth_call, + utils.udf_hex_to_int(eth_call::STRING) AS raw_balance, + raw_balance::INT / POW(10, ifnull(decimals,0)) AS balance + FROM + inputs + LEFT JOIN {{ ref('_internal__contracts_map') }} + ON token_address = address + AND blockchain = '{{blockchain}}' +) +SELECT + '{{blockchain}}' AS blockchain, + '{{network}}' AS network, + wallet_address, + token_address, + symbol, + block_number, + raw_balance, + balance +FROM final +{% endmacro %} + +{% macro evm_historical_token_balance_aaa(schema, blockchain, network) %} +WITH block_inputs AS ( + SELECT block_numbers +), +blocks AS ( + SELECT value::INTEGER AS block_number + FROM block_inputs, + LATERAL FLATTEN(input => block_numbers) +), +wallet_inputs AS ( + SELECT wallets +), +wallets AS ( + SELECT lower(value::STRING) AS wallet + FROM wallet_inputs, + LATERAL FLATTEN(input => wallets) +), +token_inputs AS ( + SELECT tokens +), +tokens AS ( + SELECT value::STRING AS token + FROM token_inputs, + LATERAL FLATTEN(input => tokens) +), +inputs AS ( + SELECT + LOWER(token) AS token_address, + wallet AS wallet_address, + '0x70a08231' AS function_sig, + CONCAT( + function_sig, + LPAD(REPLACE(wallet_address, '0x', ''), 64, '0') + ) AS data + FROM + wallets, + tokens +), +final AS ( + SELECT + wallet_address, + token_address, + symbol, + blocks.block_number, + {{schema}}.udf_rpc_eth_call(OBJECT_CONSTRUCT_KEEP_NULL('from', NULL, 'to', token_address, 'data', data), CONCAT('0x', TRIM(TO_CHAR(blocks.block_number, 'XXXXXXXXXX'))))::STRING AS eth_call, + utils.udf_hex_to_int(eth_call::STRING) AS raw_balance, + raw_balance::INT / POW(10, ifnull(decimals,0)) AS balance + FROM + inputs + CROSS JOIN blocks + LEFT JOIN {{ ref('_internal__contracts_map') }} + ON token_address = address + AND blockchain = '{{blockchain}}' +) +SELECT + '{{blockchain}}' AS blockchain, + '{{network}}' AS network, + wallet_address, + token_address, + symbol, + block_number, + raw_balance, + balance +FROM final +{% endmacro %} + +{% macro evm_historical_native_balance_si(schema, blockchain, network) %} +SELECT + '{{blockchain}}' AS blockchain, + '{{network}}' AS network, + lower(wallet) AS wallet_address, + CASE + WHEN '{{blockchain}}' ILIKE 'avalanche%' THEN 'AVAX' + WHEN '{{blockchain}}' ILIKE 'polygon%' THEN 'MATIC' + WHEN '{{blockchain}}' ILIKE 'binance%' THEN 'BNB' + WHEN '{{blockchain}}' ILIKE 'gnosis%' THEN 'xDAI' + WHEN '{{blockchain}}' ILIKE 'ethereum%' THEN 'ETH' + WHEN '{{blockchain}}' ILIKE 'arbitrum%' THEN 'ETH' + WHEN '{{blockchain}}' ILIKE 'optimism%' THEN 'ETH' + WHEN '{{blockchain}}' ILIKE 'base%' THEN 'ETH' + WHEN '{{blockchain}}' ILIKE 'fantom%' THEN 'ETH' + WHEN '{{blockchain}}' ILIKE 'harmony%' THEN 'ONE' + END AS symbol, + block_number, + utils.udf_hex_to_int({{schema}}.udf_rpc_eth_get_balance(wallet_address,CONCAT('0x', TRIM(TO_CHAR(block_number, 'XXXXXXXXXX'))))::string) AS raw_balance, + (raw_balance / POW(10,18))::float AS balance +{% endmacro %} + +{% macro evm_historical_native_balance_sa(schema, blockchain, network) %} +WITH block_inputs AS ( + SELECT block_numbers +), +blocks AS ( + SELECT value::INTEGER AS block_number + FROM block_inputs, + LATERAL FLATTEN(input => block_numbers) +), +inputs AS ( + SELECT + wallet AS wallet_address, + CASE + WHEN '{{blockchain}}' ILIKE 'avalanche%' THEN 'AVAX' + WHEN '{{blockchain}}' ILIKE 'polygon%' THEN 'MATIC' + WHEN '{{blockchain}}' ILIKE 'binance%' THEN 'BNB' + WHEN '{{blockchain}}' ILIKE 'gnosis%' THEN 'xDAI' + WHEN '{{blockchain}}' ILIKE 'ethereum%' THEN 'ETH' + WHEN '{{blockchain}}' ILIKE 'arbitrum%' THEN 'ETH' + WHEN '{{blockchain}}' ILIKE 'optimism%' THEN 'ETH' + WHEN '{{blockchain}}' ILIKE 'base%' THEN 'ETH' + WHEN '{{blockchain}}' ILIKE 'fantom%' THEN 'ETH' + WHEN '{{blockchain}}' ILIKE 'harmony%' THEN 'ONE' + END AS symbol, + block_number, + utils.udf_hex_to_int({{schema}}.udf_rpc_eth_get_balance(wallet, CONCAT('0x', TRIM(TO_CHAR(block_number, 'XXXXXXXXXX')))))::STRING AS raw_balance + FROM blocks +) +SELECT + '{{blockchain}}' AS blockchain, + '{{network}}' AS network, + wallet_address, + symbol, + block_number, + raw_balance, + (raw_balance::int / pow(10,18)) ::float as balance +FROM inputs +{% endmacro %} + +{% macro evm_historical_native_balance_ai(schema, blockchain, network) %} +WITH wallet_inputs AS ( + SELECT wallets +), +flat_wallets AS ( + SELECT lower(value::string) AS wallet + FROM wallet_inputs, + LATERAL FLATTEN(input => wallets) +), +inputs AS ( + SELECT + wallet AS wallet_address, + CASE + WHEN '{{blockchain}}' ILIKE 'avalanche%' THEN 'AVAX' + WHEN '{{blockchain}}' ILIKE 'polygon%' THEN 'MATIC' + WHEN '{{blockchain}}' ILIKE 'binance%' THEN 'BNB' + WHEN '{{blockchain}}' ILIKE 'gnosis%' THEN 'xDAI' + WHEN '{{blockchain}}' ILIKE 'ethereum%' THEN 'ETH' + WHEN '{{blockchain}}' ILIKE 'arbitrum%' THEN 'ETH' + WHEN '{{blockchain}}' ILIKE 'optimism%' THEN 'ETH' + WHEN '{{blockchain}}' ILIKE 'base%' THEN 'ETH' + WHEN '{{blockchain}}' ILIKE 'fantom%' THEN 'ETH' + WHEN '{{blockchain}}' ILIKE 'harmony%' THEN 'ONE' + END AS symbol, + block_number, + utils.udf_hex_to_int({{schema}}.udf_rpc_eth_get_balance(wallet, CONCAT('0x', TRIM(TO_CHAR(block_number, 'XXXXXXXXXX')))))::STRING AS raw_balance + FROM flat_wallets +) +SELECT + '{{blockchain}}' AS blockchain, + '{{network}}' AS network, + wallet_address, + symbol, + block_number, + raw_balance, + (raw_balance::int / pow(10,18)) ::float as balance +FROM inputs +{% endmacro %} + +{% macro evm_historical_native_balance_aa(schema, blockchain, network) %} + WITH inputs AS ( + SELECT wallets, block_numbers + ), + flat_wallets AS ( + SELECT lower(wallet.value::STRING) AS wallet, block.value::INTEGER AS block_number + FROM inputs, + LATERAL FLATTEN(input => wallets) wallet, + LATERAL FLATTEN(input => block_numbers) block + ), + final AS ( + SELECT + wallet AS wallet_address, + CASE + WHEN '{{blockchain}}' ILIKE 'avalanche%' THEN 'AVAX' + WHEN '{{blockchain}}' ILIKE 'polygon%' THEN 'MATIC' + WHEN '{{blockchain}}' ILIKE 'binance%' THEN 'BNB' + WHEN '{{blockchain}}' ILIKE 'gnosis%' THEN 'xDAI' + WHEN '{{blockchain}}' ILIKE 'ethereum%' THEN 'ETH' + WHEN '{{blockchain}}' ILIKE 'arbitrum%' THEN 'ETH' + WHEN '{{blockchain}}' ILIKE 'optimism%' THEN 'ETH' + WHEN '{{blockchain}}' ILIKE 'base%' THEN 'ETH' + WHEN '{{blockchain}}' ILIKE 'fantom%' THEN 'ETH' + WHEN '{{blockchain}}' ILIKE 'harmony%' THEN 'ONE' + END AS symbol, + block_number, + utils.udf_hex_to_int({{schema}}.udf_rpc_eth_get_balance(wallet, CONCAT('0x', TRIM(TO_CHAR(block_number, 'XXXXXXXXXX')))))::STRING AS raw_balance + FROM flat_wallets + ) + SELECT + '{{blockchain}}' AS blockchain, + '{{network}}' AS network, + wallet_address, + symbol, + block_number, + raw_balance, + (raw_balance::int / pow(10,18))::float as balance + FROM final +{% endmacro %} + +{% macro evm_latest_contract_events_s(schema, blockchain, network) %} + WITH chainhead AS ( + SELECT + {{ schema }}.udf_rpc('eth_blockNumber', [])::STRING AS chainhead_hex, + CONCAT('0x', TRIM(TO_CHAR(utils.udf_hex_to_int(chainhead_hex) - 100, 'XXXXXXXXXX'))) AS from_block_hex + ), + node_call AS ( + SELECT + lower(address) AS contract_address, + {{ schema }}.udf_rpc_eth_get_logs( + OBJECT_CONSTRUCT('address', address, 'fromBlock', from_block_hex, 'toBlock', chainhead_hex) + ) AS eth_getLogs + FROM chainhead + ), + node_flat AS ( + SELECT + contract_address, + utils.udf_hex_to_int(value:blockNumber::STRING)::INT AS block_number, + value:transactionHash::STRING AS tx_hash, + utils.udf_hex_to_int(value:transactionIndex::STRING)::INT AS tx_index, + utils.udf_hex_to_int(value:logIndex::STRING)::INT AS event_index, + value:removed::BOOLEAN AS event_removed, + value:data::STRING AS event_data, + value:topics::ARRAY AS event_topics + FROM node_call, + LATERAL FLATTEN(input => eth_getLogs) + ) + SELECT + '{{blockchain}}' AS blockchain, + '{{network}}' AS network, + tx_hash, + block_number, + event_index, + contract_address, + event_topics, + event_data + FROM node_flat +{% endmacro %} + +{% macro evm_latest_contract_events_si(schema, blockchain, network) %} + WITH chainhead AS ( + SELECT + {{ schema }}.udf_rpc('eth_blockNumber', [])::STRING AS chainhead_hex, + CONCAT('0x', TRIM(TO_CHAR(utils.udf_hex_to_int(chainhead_hex) - lookback, 'XXXXXXXXXX'))) AS from_block_hex + ), + node_call AS ( + SELECT + lower(address) AS contract_address, + {{ schema }}.udf_rpc_eth_get_logs( + OBJECT_CONSTRUCT('address', address, 'fromBlock', from_block_hex, 'toBlock', chainhead_hex) + ) AS eth_getLogs + FROM chainhead + ), + node_flat AS ( + SELECT + contract_address, + utils.udf_hex_to_int(value:blockNumber::STRING)::INT AS block_number, + value:transactionHash::STRING AS tx_hash, + utils.udf_hex_to_int(value:transactionIndex::STRING)::INT AS tx_index, + utils.udf_hex_to_int(value:logIndex::STRING)::INT AS event_index, + value:removed::BOOLEAN AS event_removed, + value:data::STRING AS event_data, + value:topics::ARRAY AS event_topics + FROM node_call, + LATERAL FLATTEN(input => eth_getLogs) + ) + SELECT + '{{blockchain}}' AS blockchain, + '{{network}}' AS network, + tx_hash, + block_number, + event_index, + contract_address, + event_topics, + event_data + FROM node_flat +{% endmacro %} + +{% macro evm_latest_contract_events_a(schema, blockchain, network) %} + WITH chainhead AS ( + SELECT + {{ schema }}.udf_rpc('eth_blockNumber', [])::STRING AS chainhead_hex, + CONCAT('0x', TRIM(TO_CHAR(utils.udf_hex_to_int(chainhead_hex) - 100, 'XXXXXXXXXX'))) AS from_block_hex + ), + node_call AS ( + SELECT + lower(address) AS contract_address, + {{ schema }}.udf_rpc_eth_get_logs( + OBJECT_CONSTRUCT('address', address, 'fromBlock', from_block_hex, 'toBlock', chainhead_hex) + ) AS eth_getLogs + FROM ( + SELECT value::STRING AS address + FROM LATERAL FLATTEN(input => addresses) + ) inputs, chainhead + ), + node_flat AS ( + SELECT + contract_address, + utils.udf_hex_to_int(value:blockNumber::STRING)::INT AS block_number, + value:transactionHash::STRING AS tx_hash, + utils.udf_hex_to_int(value:transactionIndex::STRING)::INT AS tx_index, + utils.udf_hex_to_int(value:logIndex::STRING)::INT AS event_index, + value:removed::BOOLEAN AS event_removed, + value:data::STRING AS event_data, + value:topics::ARRAY AS event_topics + FROM node_call, + LATERAL FLATTEN(input => eth_getLogs) + ) + SELECT + '{{blockchain}}' AS blockchain, + '{{network}}' AS network, + tx_hash, + block_number, + event_index, + contract_address, + event_topics, + event_data + FROM node_flat +{% endmacro %} + +{% macro evm_latest_contract_events_ai(schema, blockchain, network) %} + WITH chainhead AS ( + SELECT + {{schema }}.udf_rpc('eth_blockNumber', [])::STRING AS chainhead_hex, + CONCAT('0x', TRIM(TO_CHAR(utils.udf_hex_to_int(chainhead_hex) - lookback, 'XXXXXXXXXX'))) AS from_block_hex + ), + node_call AS ( + SELECT + lower(address) AS contract_address, + {{ schema }}.udf_rpc_eth_get_logs( + OBJECT_CONSTRUCT('address', address, 'fromBlock', from_block_hex, 'toBlock', chainhead_hex) + ) AS eth_getLogs + FROM ( + SELECT value::STRING AS address + FROM LATERAL FLATTEN(input => addresses) + ) inputs, chainhead + ), + node_flat AS ( + SELECT + contract_address, + utils.udf_hex_to_int(value:blockNumber::STRING)::INT AS block_number, + value:transactionHash::STRING AS tx_hash, + utils.udf_hex_to_int(value:transactionIndex::STRING)::INT AS tx_index, + utils.udf_hex_to_int(value:logIndex::STRING)::INT AS event_index, + value:removed::BOOLEAN AS event_removed, + value:data::STRING AS event_data, + value:topics::ARRAY AS event_topics + FROM node_call, + LATERAL FLATTEN(input => eth_getLogs) + ) + SELECT + '{{blockchain}}' AS blockchain, + '{{network}}' AS network, + tx_hash, + block_number, + event_index, + contract_address, + event_topics, + event_data + FROM node_flat +{% endmacro %} + +{% macro evm_latest_contract_events_decoded_s(schema, blockchain, network) %} +WITH inputs AS ( + SELECT lower(address::STRING) AS contract_address +), +chainhead AS ( + SELECT + {{ schema }}.udf_rpc('eth_blockNumber', [])::STRING AS chainhead_hex, + CONCAT('0x', TRIM(TO_CHAR(utils.udf_hex_to_int(chainhead_hex) - 100, 'XXXXXXXXXX'))) AS from_block_hex +), +abis AS ( + SELECT + parent_contract_address, + event_name, + event_signature, + abi + FROM inputs + JOIN {{ ref('_internal__abi_map') }} + ON lower(contract_address) = parent_contract_address + AND blockchain = '{{blockchain}}' + QUALIFY ROW_NUMBER() OVER (PARTITION BY contract_address, event_name ORDER BY end_block DESC) = 1 +), +node_call AS ( + SELECT + inputs.contract_address, + {{ schema }}.udf_rpc_eth_get_logs( + OBJECT_CONSTRUCT('address', inputs.contract_address, 'fromBlock', from_block_hex, 'toBlock', chainhead_hex) + ) AS eth_getLogs + FROM inputs + JOIN chainhead ON 1=1 +), +node_flat AS ( + SELECT + contract_address, + utils.udf_hex_to_int(value:blockNumber::STRING)::INT AS block_number, + value:transactionHash::STRING AS tx_hash, + utils.udf_hex_to_int(value:transactionIndex::STRING)::INT AS tx_index, + utils.udf_hex_to_int(value:logIndex::STRING)::INT AS event_index, + value:removed::BOOLEAN AS event_removed, + value:data::STRING AS event_data, + value:topics::ARRAY AS event_topics + FROM node_call, + LATERAL FLATTEN(input => eth_getLogs) +), +decode_logs AS ( + SELECT + contract_address, + block_number, + tx_hash, + tx_index, + event_index, + event_removed, + event_data, + event_topics, + ethereum.streamline.udf_decode( + abi, + OBJECT_CONSTRUCT( + 'topics', + event_topics, + 'data', + event_data, + 'address', + contract_address + ) + )[0] AS decoded_data, + decoded_data:name::STRING AS event_name, + ethereum.silver.udf_transform_logs(decoded_data) AS transformed + FROM node_flat + JOIN abis + ON contract_address = parent_contract_address + AND event_topics[0]::STRING = event_signature +), +final AS ( + SELECT + b.tx_hash, + b.block_number, + b.event_index, + b.event_name, + b.contract_address, + b.event_topics, + b.event_data, + b.decoded_data, + transformed, + OBJECT_AGG( + DISTINCT CASE + WHEN v.value:name = '' THEN CONCAT('anonymous_', v.index) + ELSE v.value:name + END, + v.value:value + ) AS decoded_flat + FROM decode_logs b, + LATERAL FLATTEN(input => transformed:data) v + GROUP BY + b.tx_hash, + b.block_number, + b.event_index, + b.event_name, + b.contract_address, + b.event_topics, + b.event_data, + b.decoded_data, + transformed +) +SELECT + '{{blockchain}}' AS blockchain, + '{{network}}' AS network, + n.tx_hash, + n.block_number, + n.event_index, + f.event_name, + n.contract_address, + n.event_topics, + n.event_data, + f.decoded_flat AS decoded_data +FROM node_flat n +left join final f +on n.block_number = f.block_number +and n.tx_hash = f.tx_hash +and n.event_index = f.event_index +{% endmacro %} + +{% macro evm_latest_contract_events_decoded_si(schema, blockchain, network) %} +WITH inputs AS ( + SELECT lower(address::STRING) AS contract_address +), +chainhead AS ( + SELECT + {{ schema }}.udf_rpc('eth_blockNumber', [])::STRING AS chainhead_hex, + CONCAT('0x', TRIM(TO_CHAR(utils.udf_hex_to_int(chainhead_hex) - lookback, 'XXXXXXXXXX'))) AS from_block_hex +), +abis AS ( + SELECT + parent_contract_address, + event_name, + event_signature, + abi + FROM inputs + JOIN {{ ref('_internal__abi_map') }} + ON lower(contract_address) = parent_contract_address + AND blockchain = '{{blockchain}}' + QUALIFY ROW_NUMBER() OVER (PARTITION BY contract_address, event_name ORDER BY end_block DESC) = 1 +), +node_call AS ( + SELECT + inputs.contract_address, + {{ schema }}.udf_rpc_eth_get_logs( + OBJECT_CONSTRUCT('address', inputs.contract_address, 'fromBlock', from_block_hex, 'toBlock', chainhead_hex) + ) AS eth_getLogs + FROM inputs + JOIN chainhead ON 1=1 +), +node_flat AS ( + SELECT + contract_address, + utils.udf_hex_to_int(value:blockNumber::STRING)::INT AS block_number, + value:transactionHash::STRING AS tx_hash, + utils.udf_hex_to_int(value:transactionIndex::STRING)::INT AS tx_index, + utils.udf_hex_to_int(value:logIndex::STRING)::INT AS event_index, + value:removed::BOOLEAN AS event_removed, + value:data::STRING AS event_data, + value:topics::ARRAY AS event_topics + FROM node_call, + LATERAL FLATTEN(input => eth_getLogs) +), +decode_logs AS ( + SELECT + contract_address, + block_number, + tx_hash, + tx_index, + event_index, + event_removed, + event_data, + event_topics, + ethereum.streamline.udf_decode( + abi, + OBJECT_CONSTRUCT( + 'topics', + event_topics, + 'data', + event_data, + 'address', + contract_address + ) + )[0] AS decoded_data, + decoded_data:name::STRING AS event_name, + ethereum.silver.udf_transform_logs(decoded_data) AS transformed + FROM node_flat + JOIN abis + ON contract_address = parent_contract_address + AND event_topics[0]::STRING = event_signature +), +final AS ( + SELECT + b.tx_hash, + b.block_number, + b.event_index, + b.event_name, + b.contract_address, + b.event_topics, + b.event_data, + b.decoded_data, + transformed, + OBJECT_AGG( + DISTINCT CASE + WHEN v.value:name = '' THEN CONCAT('anonymous_', v.index) + ELSE v.value:name + END, + v.value:value + ) AS decoded_flat + FROM decode_logs b, + LATERAL FLATTEN(input => transformed:data) v + GROUP BY + b.tx_hash, + b.block_number, + b.event_index, + b.event_name, + b.contract_address, + b.event_topics, + b.event_data, + b.decoded_data, + transformed +) +SELECT + '{{blockchain}}' AS blockchain, + '{{network}}' AS network, + n.tx_hash, + n.block_number, + n.event_index, + f.event_name, + n.contract_address, + n.event_topics, + n.event_data, + f.decoded_flat AS decoded_data +FROM node_flat n +left join final f +on n.block_number = f.block_number +and n.tx_hash = f.tx_hash +and n.event_index = f.event_index +{% endmacro %} + +{% macro evm_latest_contract_events_decoded_a(schema, blockchain, network) %} +WITH base AS (SELECT addresses), +inputs AS ( + SELECT lower(value::STRING) AS contract_address + FROM base, LATERAL FLATTEN(input => addresses) +), +chainhead AS ( + SELECT + {{ schema }}.udf_rpc('eth_blockNumber', [])::STRING AS chainhead_hex, + CONCAT('0x', TRIM(TO_CHAR(utils.udf_hex_to_int(chainhead_hex) - 100, 'XXXXXXXXXX'))) AS from_block_hex +), +abis AS ( + SELECT + parent_contract_address, + event_name, + event_signature, + abi + FROM inputs + JOIN {{ ref('_internal__abi_map') }} + ON lower(contract_address) = parent_contract_address + AND blockchain = '{{blockchain}}' + QUALIFY ROW_NUMBER() OVER (PARTITION BY contract_address, event_name ORDER BY end_block DESC) = 1 +), +node_call AS ( + SELECT + inputs.contract_address, + {{ schema }}.udf_rpc_eth_get_logs( + OBJECT_CONSTRUCT('address', inputs.contract_address, 'fromBlock', from_block_hex, 'toBlock', chainhead_hex) + ) AS eth_getLogs + FROM inputs + JOIN chainhead ON 1=1 +), +node_flat AS ( + SELECT + contract_address, + utils.udf_hex_to_int(value:blockNumber::STRING)::INT AS block_number, + value:transactionHash::STRING AS tx_hash, + utils.udf_hex_to_int(value:transactionIndex::STRING)::INT AS tx_index, + utils.udf_hex_to_int(value:logIndex::STRING)::INT AS event_index, + value:removed::BOOLEAN AS event_removed, + value:data::STRING AS event_data, + value:topics::ARRAY AS event_topics + FROM node_call, + LATERAL FLATTEN(input => eth_getLogs) +), +decode_logs AS ( + SELECT + contract_address, + block_number, + tx_hash, + tx_index, + event_index, + event_removed, + event_data, + event_topics, + ethereum.streamline.udf_decode( + abi, + OBJECT_CONSTRUCT( + 'topics', + event_topics, + 'data', + event_data, + 'address', + contract_address + ) + )[0] AS decoded_data, + decoded_data:name::STRING AS event_name, + ethereum.silver.udf_transform_logs(decoded_data) AS transformed + FROM node_flat + JOIN abis + ON contract_address = parent_contract_address + AND event_topics[0]::STRING = event_signature +), +final AS ( + SELECT + b.tx_hash, + b.block_number, + b.event_index, + b.event_name, + b.contract_address, + b.event_topics, + b.event_data, + b.decoded_data, + transformed, + OBJECT_AGG( + DISTINCT CASE + WHEN v.value:name = '' THEN CONCAT('anonymous_', v.index) + ELSE v.value:name + END, + v.value:value + ) AS decoded_flat + FROM decode_logs b, + LATERAL FLATTEN(input => transformed:data) v + GROUP BY + b.tx_hash, + b.block_number, + b.event_index, + b.event_name, + b.contract_address, + b.event_topics, + b.event_data, + b.decoded_data, + transformed +) +SELECT + '{{blockchain}}' AS blockchain, + '{{network}}' AS network, + n.tx_hash, + n.block_number, + n.event_index, + f.event_name, + n.contract_address, + n.event_topics, + n.event_data, + f.decoded_flat AS decoded_data +FROM node_flat n +left join final f +on n.block_number = f.block_number +and n.tx_hash = f.tx_hash +and n.event_index = f.event_index +{% endmacro %} + +{% macro evm_latest_contract_events_decoded_ai(schema, blockchain, network) %} +WITH base AS (SELECT addresses), +inputs AS ( + SELECT lower(value::STRING) AS contract_address + FROM base, LATERAL FLATTEN(input => addresses) +), +chainhead AS ( + SELECT + {{ schema }}.udf_rpc('eth_blockNumber', [])::STRING AS chainhead_hex, + CONCAT('0x', TRIM(TO_CHAR(utils.udf_hex_to_int(chainhead_hex) - lookback, 'XXXXXXXXXX'))) AS from_block_hex +), +abis AS ( + SELECT + parent_contract_address, + event_name, + event_signature, + abi + FROM inputs + JOIN {{ ref('_internal__abi_map') }} + ON lower(contract_address) = parent_contract_address + AND blockchain = '{{blockchain}}' + QUALIFY ROW_NUMBER() OVER (PARTITION BY contract_address, event_name ORDER BY end_block DESC) = 1 +), +node_call AS ( + SELECT + inputs.contract_address, + {{ schema }}.udf_rpc_eth_get_logs( + OBJECT_CONSTRUCT('address', inputs.contract_address, 'fromBlock', from_block_hex, 'toBlock', chainhead_hex) + ) AS eth_getLogs + FROM inputs + JOIN chainhead ON 1=1 +), +node_flat AS ( + SELECT + contract_address, + utils.udf_hex_to_int(value:blockNumber::STRING)::INT AS block_number, + value:transactionHash::STRING AS tx_hash, + utils.udf_hex_to_int(value:transactionIndex::STRING)::INT AS tx_index, + utils.udf_hex_to_int(value:logIndex::STRING)::INT AS event_index, + value:removed::BOOLEAN AS event_removed, + value:data::STRING AS event_data, + value:topics::ARRAY AS event_topics + FROM node_call, + LATERAL FLATTEN(input => eth_getLogs) +), +decode_logs AS ( + SELECT + contract_address, + block_number, + tx_hash, + tx_index, + event_index, + event_removed, + event_data, + event_topics, + ethereum.streamline.udf_decode( + abi, + OBJECT_CONSTRUCT( + 'topics', + event_topics, + 'data', + event_data, + 'address', + contract_address + ) + )[0] AS decoded_data, + decoded_data:name::STRING AS event_name, + ethereum.silver.udf_transform_logs(decoded_data) AS transformed + FROM node_flat + JOIN abis + ON contract_address = parent_contract_address + AND event_topics[0]::STRING = event_signature +), +final AS ( + SELECT + b.tx_hash, + b.block_number, + b.event_index, + b.event_name, + b.contract_address, + b.event_topics, + b.event_data, + b.decoded_data, + transformed, + OBJECT_AGG( + DISTINCT CASE + WHEN v.value:name = '' THEN CONCAT('anonymous_', v.index) + ELSE v.value:name + END, + v.value:value + ) AS decoded_flat + FROM decode_logs b, + LATERAL FLATTEN(input => transformed:data) v + GROUP BY + b.tx_hash, + b.block_number, + b.event_index, + b.event_name, + b.contract_address, + b.event_topics, + b.event_data, + b.decoded_data, + transformed +) +SELECT + '{{blockchain}}' AS blockchain, + '{{network}}' AS network, + n.tx_hash, + n.block_number, + n.event_index, + f.event_name, + n.contract_address, + n.event_topics, + n.event_data, + f.decoded_flat AS decoded_data +FROM node_flat n +left join final f +on n.block_number = f.block_number +and n.tx_hash = f.tx_hash +and n.event_index = f.event_index +{% endmacro %} diff --git a/macros/livequery/evm_primitives.yaml.sql b/macros/livequery/evm_primitives.yaml.sql index c0421f3..555ad5b 100644 --- a/macros/livequery/evm_primitives.yaml.sql +++ b/macros/livequery/evm_primitives.yaml.sql @@ -1,13 +1,29 @@ -{%- macro config_evm_rpc_primitives(schema, blockchain) -%} +{%- macro config_evm_rpc_primitives(blockchain, network) -%} {#- Generates a set of UDFs that call the Ethereum JSON RPC API - - eth_call - - eth_getLogs - - eth_getBalance + - rpc: Executes an RPC call on the {{ blockchain }} blockchain + - eth_call: Executes a new message call immediately without creating a transaction on the block chain + - eth_getLogs: Returns an array of all logs matching filter with given address + - eth_getBalance: Returns the balance of the account of given address -#} -- name: {{ schema -}}.rpc_eth_call +{% set schema = blockchain ~ "_" ~ network -%} + +- name: {{ schema -}}.udf_rpc + signature: + - [method, STRING, RPC method to call] + - [parameters, VARIANT, Parameters to pass to the RPC method] + return_type: [VARIANT, The return value of the RPC method] + options: | + NOT NULL + RETURNS NULL ON NULL INPUT + VOLATILE + COMMENT = $$Executes an RPC call on the {{ blockchain }} blockchain.$$ + sql: | + SELECT live.udf_rpc('{{ blockchain }}', '{{ network }}', method, parameters) + +- name: {{ schema -}}.udf_rpc_eth_call signature: - [transaction, OBJECT, The transaction object] - [block_or_tag, STRING, The block number or tag to execute the call on] @@ -18,22 +34,9 @@ VOLATILE COMMENT = $$Executes a new message call immediately without creating a transaction on the block chain.$$ sql: | - {{ sql_live_rpc_call('eth_call', "[transaction, block_or_tag]", blockchain, "'mainnet'") | indent(4) -}} -- name: {{ schema -}}.rpc_eth_call - signature: - - [transaction, OBJECT, The transaction object] - - [block_or_tag, STRING, The block number or tag to execute the call on] - - [network, STRING, The network to execute the call on] - return_type: [VARIANT, The return value of the executed contract code] - options: | - NOT NULL - RETURNS NULL ON NULL INPUT - VOLATILE - COMMENT = $$Executes a new message call immediately without creating a transaction on the block chain.$$ - sql: | - {{ sql_live_rpc_call('eth_call', '[transaction, block_or_tag]', blockchain, 'network') | indent(4) -}} + SELECT {{ schema -}}.udf_rpc('eth_call', [transaction, block_or_tag]) -- name: {{ schema -}}.rpc_eth_get_logs +- name: {{ schema -}}.udf_rpc_eth_get_logs signature: - [filter, OBJECT, The filter object] return_type: [VARIANT, An array of all logs matching filter with given address] @@ -43,21 +46,9 @@ VOLATILE COMMENT = $$Returns an array of all logs matching filter with given address.$$ sql: | - {{ sql_live_rpc_call('eth_getLogs', '[filter]', blockchain, "'mainnet'") | indent(4) -}} -- name: {{ schema -}}.rpc_eth_get_logs - signature: - - [filter, OBJECT, The filter object] - - [network, STRING, The network to execute the call on] - return_type: [VARIANT, An array of all logs matching filter with given address] - options: | - NOT NULL - RETURNS NULL ON NULL INPUT - VOLATILE - COMMENT = $$Returns an array of all logs matching filter with given address.$$ - sql: | - {{ sql_live_rpc_call('eth_getLogs', '[filter]', blockchain, 'network') | indent(4) -}} + SELECT {{ schema -}}.udf_rpc('eth_getLogs', [filter]) -- name: {{ schema -}}.rpc_eth_get_balance +- name: {{ schema -}}.udf_rpc_eth_get_balance signature: - [address, STRING, The address to get the balance of] - [block_or_tag, STRING, The block number or tag to execute the call on] @@ -68,18 +59,6 @@ VOLATILE COMMENT = $$Returns the balance of the account of given address.$$ sql: | - {{ sql_live_rpc_call('eth_getBalance', '[address, block_or_tag]', blockchain, "'mainnet'") | indent(4) -}} -- name: {{ schema -}}.rpc_eth_get_balance - signature: - - [address, STRING, The address to get the balance of] - - [block_or_tag, STRING, The block number or tag to execute the call on] - - [network, STRING, The network to execute the call on] - return_type: [VARIANT, The balance of the account of given address] - options: | - NOT NULL - RETURNS NULL ON NULL INPUT - VOLATILE - COMMENT = $$Returns the balance of the account of given address.$$ - sql: | - {{ sql_live_rpc_call('eth_getBalance', '[address, block_or_tag]', blockchain, 'network') | indent(4) -}} -{% endmacro -%} + SELECT {{ schema -}}.udf_rpc('eth_getBalance', [address, block_or_tag]) + +{%- endmacro -%} diff --git a/macros/livequery/utils.sql b/macros/livequery/utils.sql index 5ef9e88..3da87bd 100644 --- a/macros/livequery/utils.sql +++ b/macros/livequery/utils.sql @@ -14,11 +14,11 @@ SELECT live.udf_api( '{endpoint}' - ,utils.udf_json_rpc_call('{{ method }}', {{ params }}) - ,concat_ws('/', 'integration', _utils.udf_provider(), '{{ blockchain }}', {{ network }}) + ,utils.udf_json_rpc_call({{ method }}, {{ params }}) + ,concat_ws('/', 'integration', _utils.udf_provider(), {{ blockchain }}, {{ network }}) )::VARIANT:data AS data ) SELECT COALESCE(data:result, {'error':data:error}) FROM result -{%- endmacro -%} \ No newline at end of file +{% endmacro -%} \ No newline at end of file diff --git a/models/_internal__abi_map.sql b/models/_internal__abi_map.sql new file mode 100644 index 0000000..b679e1a --- /dev/null +++ b/models/_internal__abi_map.sql @@ -0,0 +1,22 @@ +{{ config( + materialized = 'view' +) }} + +SELECT + parent_contract_address, + event_name, + event_signature, + abi, + start_block, + end_block, + CASE + blockchain + WHEN 'avalanche' THEN 'avalanche_c' + WHEN 'arbitrum' THEN 'arbitrum_one' + ELSE blockchain + END AS blockchain +FROM + {{ source( + 'crosschain', + 'dim_evm_event_abis' + ) }} diff --git a/models/_internal__contracts_map.sql b/models/_internal__contracts_map.sql new file mode 100644 index 0000000..6f48eff --- /dev/null +++ b/models/_internal__contracts_map.sql @@ -0,0 +1,19 @@ +{{ config( + materialized = 'view' +) }} + +SELECT + address, + symbol, + decimals, + CASE + blockchain + WHEN 'avalanche' THEN 'avalanche_c' + WHEN 'arbitrum' THEN 'arbitrum_one' + ELSE blockchain + END AS blockchain +FROM + {{ source( + 'crosschain', + 'dim_contracts' + ) }} diff --git a/models/sources.yml b/models/sources.yml index 6267a2e..69dc78a 100644 --- a/models/sources.yml +++ b/models/sources.yml @@ -5,4 +5,6 @@ sources: database: "{{ 'crosschain' if target.database == 'LIVEQUERY' else 'crosschain_dev' }}" schema: core tables: - - name: dim_date_hours \ No newline at end of file + - name: dim_date_hours + - name: dim_contracts + - name: dim_evm_event_abis \ No newline at end of file