diff --git a/models/bronze/decoder/bronze_testnet__decoded_logs.sql b/models/bronze/decoder/bronze_testnet__decoded_logs.sql new file mode 100644 index 0000000..32c23cb --- /dev/null +++ b/models/bronze/decoder/bronze_testnet__decoded_logs.sql @@ -0,0 +1,41 @@ +{{ config ( + materialized = 'view' +) }} + +WITH meta AS ( + + SELECT + last_modified AS _inserted_timestamp, + file_name, + CAST(SPLIT_PART(SPLIT_PART(file_name, '/', 6), '_', 1) AS INTEGER) AS _partition_by_block_number, + TO_DATE( + concat_ws('-', SPLIT_PART(file_name, '/', 3), SPLIT_PART(file_name, '/', 4), SPLIT_PART(file_name, '/', 5)) + ) AS _partition_by_created_date + FROM + TABLE( + information_schema.external_table_file_registration_history( + start_time => DATEADD('day', -3, CURRENT_TIMESTAMP()), + table_name => '{{ source( "bronze_streamline", "testnet_decoded_logs") }}') + ) A + ) + SELECT + block_number, + id :: STRING AS id, + DATA, + _inserted_timestamp, + s._partition_by_block_number AS _partition_by_block_number, + s._partition_by_created_date AS _partition_by_created_date + FROM + {{ source( + "bronze_streamline", + "testnet_decoded_logs" + ) }} + s + JOIN meta b + ON b.file_name = metadata$filename + AND b._partition_by_block_number = s._partition_by_block_number + AND b._partition_by_created_date = s._partition_by_created_date + WHERE + b._partition_by_block_number = s._partition_by_block_number + AND b._partition_by_created_date = s._partition_by_created_date + AND s._partition_by_created_date >= DATEADD('day', -2, CURRENT_TIMESTAMP()) diff --git a/models/bronze/decoder/bronze_testnet__fr_decoded_logs.sql b/models/bronze/decoder/bronze_testnet__fr_decoded_logs.sql new file mode 100644 index 0000000..0b6793d --- /dev/null +++ b/models/bronze/decoder/bronze_testnet__fr_decoded_logs.sql @@ -0,0 +1,40 @@ +{{ config ( + materialized = 'view' +) }} + +WITH meta AS ( + + SELECT + registered_on AS _inserted_timestamp, + file_name, + CAST(SPLIT_PART(SPLIT_PART(file_name, '/', 6), '_', 1) AS INTEGER) AS _partition_by_block_number, + TO_DATE( + concat_ws('-', SPLIT_PART(file_name, '/', 3), SPLIT_PART(file_name, '/', 4), SPLIT_PART(file_name, '/', 5)) + ) AS _partition_by_created_date + FROM + TABLE( + information_schema.external_table_files( + table_name => '{{ source( "bronze_streamline", "testnet_decoded_logs") }}' + ) + ) A +) +SELECT + block_number, + id :: STRING AS id, + DATA, + _inserted_timestamp, + s._partition_by_block_number AS _partition_by_block_number, + s._partition_by_created_date AS _partition_by_created_date +FROM + {{ source( + "bronze_streamline", + "testnet_decoded_logs" + ) }} + s + JOIN meta b + ON b.file_name = metadata$filename + AND b._partition_by_block_number = s._partition_by_block_number + AND b._partition_by_created_date = s._partition_by_created_date +WHERE + b._partition_by_block_number = s._partition_by_block_number + AND b._partition_by_created_date = s._partition_by_created_date diff --git a/models/silver/abis/silver_testnet__abis.sql b/models/silver/abis/silver_testnet__abis.sql new file mode 100644 index 0000000..5db4c80 --- /dev/null +++ b/models/silver/abis/silver_testnet__abis.sql @@ -0,0 +1,181 @@ +{{ config ( + materialized = "incremental", + unique_key = "contract_address", + merge_exclude_columns = ["inserted_timestamp"], + post_hook = "ALTER TABLE {{ this }} ADD SEARCH OPTIMIZATION ON EQUALITY(contract_address,abi_hash,bytecode), SUBSTRING(contract_address,abi_hash,bytecode)", + tags = ['abis'] +) }} + +WITH override_abis AS ( + + SELECT + contract_address, + PARSE_JSON(DATA) AS abi, + TO_TIMESTAMP_LTZ(SYSDATE()) AS _inserted_timestamp, + 'flipside' AS abi_source, + 'flipside' AS discord_username, + SHA2(abi) AS abi_hash, + 1 AS priority + FROM + {{ ref('silver_testnet__override_abis') }} + WHERE + contract_address IS NOT NULL +), +verified_abis AS ( + SELECT + contract_address, + DATA, + _inserted_timestamp, + abi_source, + discord_username, + abi_hash, + 2 AS priority + FROM + {{ ref('silver_testnet__verified_abis') }} + WHERE + abi_source = 'routescan' + +{% if is_incremental() %} +AND _inserted_timestamp >= ( + SELECT + MAX( + _inserted_timestamp + ) + FROM + {{ this }} + WHERE + abi_source = 'routescan' +) +{% endif %} +), +user_abis AS ( + SELECT + contract_address, + DATA, + _inserted_timestamp, + abi_source, + discord_username, + abi_hash, + 2 AS priority + FROM + {{ ref('silver_testnet__verified_abis') }} + WHERE + abi_source = 'user' + +{% if is_incremental() %} +AND _inserted_timestamp >= ( + SELECT + MAX( + _inserted_timestamp + ) + FROM + {{ this }} + WHERE + abi_source = 'user' +) +{% endif %} +), +bytecode_abis AS ( + SELECT + contract_address, + abi, + abi_hash, + 'bytecode_matched' AS abi_source, + NULL AS discord_username, + _inserted_timestamp, + 3 AS priority + FROM + {{ ref('silver_testnet__bytecode_abis') }} + WHERE + 1 = 1 + +{% if is_incremental() %} +AND _inserted_timestamp >= ( + SELECT + MAX( + _inserted_timestamp + ) + FROM + {{ this }} + WHERE + abi_source = 'bytecode_matched' +) +{% endif %} +), +all_abis AS ( + SELECT + contract_address, + abi AS DATA, + _inserted_timestamp, + abi_source, + discord_username, + abi_hash, + priority + FROM + override_abis + UNION + SELECT + contract_address, + DATA, + _inserted_timestamp, + abi_source, + discord_username, + abi_hash, + priority + FROM + verified_abis + UNION + SELECT + contract_address, + DATA, + _inserted_timestamp, + abi_source, + discord_username, + abi_hash, + priority + FROM + user_abis + UNION + SELECT + contract_address, + abi AS DATA, + _inserted_timestamp, + abi_source, + discord_username, + abi_hash, + priority + FROM + bytecode_abis +), +priority_abis AS ( + SELECT + contract_address, + DATA, + _inserted_timestamp, + abi_source, + discord_username, + abi_hash, + priority + FROM + all_abis qualify(ROW_NUMBER() over(PARTITION BY contract_address + ORDER BY + priority ASC)) = 1 +) +SELECT + p.contract_address, + p.data, + p._inserted_timestamp, + p.abi_source, + p.discord_username, + p.abi_hash, + created_contract_input AS bytecode, + {{ dbt_utils.generate_surrogate_key( + ['contract_address'] + ) }} AS abis_id, + SYSDATE() AS inserted_timestamp, + SYSDATE() AS modified_timestamp, + '{{ invocation_id }}' AS _invocation_id +FROM + priority_abis p + LEFT JOIN {{ ref('silver_testnet__created_contracts') }} + ON p.contract_address = created_contract_address diff --git a/models/silver/abis/silver_testnet__abis.yml b/models/silver/abis/silver_testnet__abis.yml new file mode 100644 index 0000000..f862904 --- /dev/null +++ b/models/silver/abis/silver_testnet__abis.yml @@ -0,0 +1,8 @@ + +version: 2 +models: + - name: silver_testnet__abis + tests: + - dbt_utils.unique_combination_of_columns: + combination_of_columns: + - CONTRACT_ADDRESS \ No newline at end of file diff --git a/models/silver/abis/silver_testnet__bytecode_abis.sql b/models/silver/abis/silver_testnet__bytecode_abis.sql new file mode 100644 index 0000000..4095b89 --- /dev/null +++ b/models/silver/abis/silver_testnet__bytecode_abis.sql @@ -0,0 +1,76 @@ +{{ config ( + materialized = "incremental", + unique_key = "contract_address", + tags = ['abis'] +) }} + +WITH contracts_with_abis AS ( + -- Identifying contracts with verified ABIs + + SELECT + created_contract_address AS contract_address + FROM + {{ ref('silver_testnet__created_contracts') }} + JOIN {{ ref('silver_testnet__verified_abis') }} A + ON A.contract_address = created_contract_address +), +contracts_without_abis AS ( + -- Contracts that are missing ABIs + SELECT + created_contract_address AS contract_address, + created_contract_input AS bytecode + FROM + {{ ref('silver_testnet__created_contracts') }} + WHERE + created_contract_address NOT IN ( + SELECT + contract_address + FROM + contracts_with_abis + ) + +{% if is_incremental() %} +AND created_contract_address NOT IN ( + SELECT + contract_address + FROM + {{ this }} +) +{% endif %} +), +unique_bytecode_abis AS ( + -- Bytecodes from created_contracts with a unique ABI + SELECT + cc.created_contract_input AS bytecode, + va.data AS abi, + va.abi_hash + FROM + {{ ref('silver_testnet__created_contracts') }} + cc + JOIN {{ ref('silver_testnet__verified_abis') }} + va + ON cc.created_contract_address = va.contract_address + GROUP BY + cc.created_contract_input, + va.data, + va.abi_hash + HAVING + COUNT( + DISTINCT va.data + ) = 1 -- Ensuring there's only one ABI per bytecode +) -- Final matching +SELECT + contract_address, + abi, + abi_hash, + +{% if is_incremental() %} +SYSDATE() +{% else %} + TO_TIMESTAMP_NTZ('2000-01-01 00:00:00') +{% endif %} + +AS _inserted_timestamp +FROM + contracts_without_abis + JOIN unique_bytecode_abis USING (bytecode) diff --git a/models/silver/abis/silver_testnet__bytecode_abis.yml b/models/silver/abis/silver_testnet__bytecode_abis.yml new file mode 100644 index 0000000..77273c4 --- /dev/null +++ b/models/silver/abis/silver_testnet__bytecode_abis.yml @@ -0,0 +1,8 @@ +version: 2 +models: + - name: silver_testnet__bytecode_abis + tests: + - dbt_utils.unique_combination_of_columns: + combination_of_columns: + - CONTRACT_ADDRESS + - ABI_HASH \ No newline at end of file diff --git a/models/silver/abis/silver_testnet__complete_event_abis.sql b/models/silver/abis/silver_testnet__complete_event_abis.sql new file mode 100644 index 0000000..32c2957 --- /dev/null +++ b/models/silver/abis/silver_testnet__complete_event_abis.sql @@ -0,0 +1,216 @@ +{{ config ( + materialized = 'incremental', + unique_key = ['parent_contract_address','event_signature','start_block'], + merge_exclude_columns = ["inserted_timestamp"], + post_hook = "ALTER TABLE {{ this }} ADD SEARCH OPTIMIZATION", + tags = ['abis'] +) }} + +WITH new_abis AS ( + + SELECT + DISTINCT contract_address + FROM + {{ ref('silver_testnet__flat_event_abis') }} + +{% if is_incremental() %} +WHERE + _inserted_timestamp >= ( + SELECT + MAX(_inserted_timestamp) - INTERVAL '12 hours' + FROM + {{ this }} + ) +{% endif %} +), +proxies AS ( + SELECT + p0.created_block, + p0.proxy_created_block, + p0.contract_address, + p0.proxy_address, + p0.start_block, + p0._id, + p0._inserted_timestamp + FROM + {{ ref('silver_testnet__proxies') }} + p0 + JOIN new_abis na0 + ON p0.contract_address = na0.contract_address + UNION + SELECT + p1.created_block, + p1.proxy_created_block, + p1.contract_address, + p1.proxy_address, + p1.start_block, + p1._id, + p1._inserted_timestamp + FROM + {{ ref('silver_testnet__proxies') }} + p1 + JOIN new_abis na1 + ON p1.proxy_address = na1.contract_address +), +all_relevant_contracts AS ( + SELECT + DISTINCT contract_address + FROM + proxies + UNION + SELECT + DISTINCT proxy_address AS contract_address + FROM + proxies + UNION + SELECT + contract_address + FROM + new_abis +), +flat_abis AS ( + SELECT + contract_address, + event_name, + abi, + simple_event_name, + event_signature, + NAME, + inputs, + event_type, + _inserted_timestamp + FROM + {{ ref('silver_testnet__flat_event_abis') }} + JOIN all_relevant_contracts USING (contract_address) +), +base AS ( + SELECT + ea.contract_address, + event_name, + abi, + simple_event_name, + event_signature, + NAME, + inputs, + event_type, + ea._inserted_timestamp, + pb._inserted_timestamp AS proxy_inserted_timestamp, + pb.start_block, + pb.proxy_created_block, + pb.contract_address AS base_contract_address, + 1 AS priority + FROM + flat_abis ea + JOIN proxies pb + ON ea.contract_address = pb.proxy_address + UNION ALL + SELECT + eab.contract_address, + event_name, + abi, + simple_event_name, + event_signature, + NAME, + inputs, + event_type, + eab._inserted_timestamp, + pbb._inserted_timestamp AS proxy_inserted_timestamp, + pbb.created_block AS start_block, + pbb.proxy_created_block, + pbb.contract_address AS base_contract_address, + 2 AS priority + FROM + flat_abis eab + JOIN ( + SELECT + DISTINCT contract_address, + created_block, + proxy_created_block, + _inserted_timestamp + FROM + proxies + ) pbb + ON eab.contract_address = pbb.contract_address + UNION ALL + SELECT + contract_address, + event_name, + abi, + simple_event_name, + event_signature, + NAME, + inputs, + event_type, + _inserted_timestamp, + NULL AS proxy_inserted_timestamp, + 0 AS start_block, + NULL AS proxy_created_block, + contract_address AS base_contract_address, + 3 AS priority + FROM + flat_abis eac + WHERE + contract_address NOT IN ( + SELECT + DISTINCT contract_address + FROM + proxies + ) +), +new_records AS ( + SELECT + base_contract_address AS parent_contract_address, + event_name, + abi, + start_block, + proxy_created_block, + simple_event_name, + event_signature, + NAME, + inputs, + event_type, + _inserted_timestamp, + proxy_inserted_timestamp + FROM + base qualify ROW_NUMBER() over ( + PARTITION BY parent_contract_address, + NAME, + event_type, + event_signature, + start_block + ORDER BY + priority ASC, + _inserted_timestamp DESC, + proxy_created_block DESC nulls last, + proxy_inserted_timestamp DESC nulls last + ) = 1 +) +SELECT + parent_contract_address, + event_name, + abi, + start_block, + proxy_created_block, + simple_event_name, + event_signature, + IFNULL(LEAD(start_block) over (PARTITION BY parent_contract_address, event_signature +ORDER BY + start_block) -1, 1e18) AS end_block, + _inserted_timestamp, + proxy_inserted_timestamp, + SYSDATE() AS _updated_timestamp, + {{ dbt_utils.generate_surrogate_key( + ['parent_contract_address','event_signature','start_block'] + ) }} AS complete_event_abis_id, + SYSDATE() AS inserted_timestamp, + SYSDATE() AS modified_timestamp, + '{{ invocation_id }}' AS _invocation_id +FROM + new_records qualify ROW_NUMBER() over ( + PARTITION BY parent_contract_address, + event_name, + event_signature, + start_block + ORDER BY + _inserted_timestamp DESC + ) = 1 diff --git a/models/silver/abis/silver_testnet__complete_event_abis.yml b/models/silver/abis/silver_testnet__complete_event_abis.yml new file mode 100644 index 0000000..0676e12 --- /dev/null +++ b/models/silver/abis/silver_testnet__complete_event_abis.yml @@ -0,0 +1,9 @@ +version: 2 +models: + - name: silver_testnet__complete_event_abis + tests: + - dbt_utils.unique_combination_of_columns: + combination_of_columns: + - PARENT_CONTRACT_ADDRESS + - EVENT_SIGNATURE + - START_BLOCK \ No newline at end of file diff --git a/models/silver/abis/silver_testnet__flat_event_abis.sql b/models/silver/abis/silver_testnet__flat_event_abis.sql new file mode 100644 index 0000000..3f8be64 --- /dev/null +++ b/models/silver/abis/silver_testnet__flat_event_abis.sql @@ -0,0 +1,112 @@ +{{ config ( + materialized = 'incremental', + incremental_strategy = 'delete+insert', + unique_key = 'contract_address', + cluster_by = '_inserted_timestamp::date', + tags = ['abis'], + post_hook = "ALTER TABLE {{ this }} ADD SEARCH OPTIMIZATION ON EQUALITY (contract_address)" +) }} + +WITH abi_base AS ( + + SELECT + contract_address, + DATA, + _inserted_timestamp + FROM + {{ ref('silver_testnet__abis') }} + +{% if is_incremental() %} +WHERE + _inserted_timestamp >= ( + SELECT + MAX(_inserted_timestamp) - INTERVAL '24 hours' + FROM + {{ this }} + ) +{% endif %} +), +flat_abi AS ( + SELECT + contract_address, + _inserted_timestamp, + DATA, + VALUE :inputs AS inputs, + VALUE :payable :: BOOLEAN AS payable, + VALUE :stateMutability :: STRING AS stateMutability, + VALUE :type :: STRING AS TYPE, + VALUE :anonymous :: BOOLEAN AS anonymous, + VALUE :name :: STRING AS NAME + FROM + abi_base, + LATERAL FLATTEN ( + input => DATA + ) + WHERE + TYPE = 'event' qualify ROW_NUMBER() over ( + PARTITION BY contract_address, + NAME, + inputs + ORDER BY + LENGTH(inputs) + ) = 1 +), +event_types AS ( + SELECT + contract_address, + _inserted_timestamp, + inputs, + anonymous, + NAME, + ARRAY_AGG( + VALUE :type :: STRING + ) AS event_type + FROM + flat_abi, + LATERAL FLATTEN ( + input => inputs + ) + GROUP BY + contract_address, + _inserted_timestamp, + inputs, + anonymous, + NAME +), +apply_udfs AS ( + SELECT + contract_address, + NAME AS event_name, + PARSE_JSON( + OBJECT_CONSTRUCT( + 'anonymous', + anonymous, + 'inputs', + inputs, + 'name', + NAME, + 'type', + 'event' + ) :: STRING + ) AS abi, + utils.udf_evm_text_signature(abi) AS simple_event_name, + utils.udf_keccak256(simple_event_name) AS event_signature, + NAME, + inputs, + event_type, + _inserted_timestamp + FROM + event_types +) +SELECT + contract_address, + event_name, + abi, + simple_event_name, + event_signature, + NAME, + inputs, + event_type, + _inserted_timestamp +FROM + apply_udfs diff --git a/models/silver/abis/silver_testnet__override_abis.sql b/models/silver/abis/silver_testnet__override_abis.sql new file mode 100644 index 0000000..88b8439 --- /dev/null +++ b/models/silver/abis/silver_testnet__override_abis.sql @@ -0,0 +1,8 @@ +{{ config( + materialized = 'view', + tags = ['abis'] +) }} + +SELECT + NULL AS contract_address, + NULL AS DATA diff --git a/models/silver/abis/silver_testnet__proxies.sql b/models/silver/abis/silver_testnet__proxies.sql new file mode 100644 index 0000000..30ea4e6 --- /dev/null +++ b/models/silver/abis/silver_testnet__proxies.sql @@ -0,0 +1,104 @@ +{{ config ( + materialized = 'incremental', + unique_key = ['contract_address','proxy_address'], + post_hook = "ALTER TABLE {{ this }} ADD SEARCH OPTIMIZATION", + tags = ['abis'] +) }} + +WITH base AS ( + + SELECT + from_address, + to_address, + MIN(block_number) AS start_block, + MAX(_inserted_timestamp) AS _inserted_timestamp + FROM + {{ ref('silver_testnet__traces') }} + WHERE + TYPE = 'DELEGATECALL' + AND trace_status = 'SUCCESS' + AND tx_status + AND from_address != to_address -- exclude self-calls + +{% if is_incremental() %} +AND _inserted_timestamp >= ( + SELECT + MAX(_inserted_timestamp) - INTERVAL '24 hours' + FROM + {{ this }} +) +{% endif %} +GROUP BY + from_address, + to_address +), +create_id AS ( + SELECT + from_address AS contract_address, + to_address AS proxy_address, + start_block, + CONCAT( + from_address, + '-', + to_address + ) AS _id, + _inserted_timestamp + FROM + base +), +heal AS ( + SELECT + contract_address, + proxy_address, + start_block, + _id, + _inserted_timestamp + FROM + create_id + +{% if is_incremental() %} +UNION ALL +SELECT + contract_address, + proxy_address, + start_block, + _id, + _inserted_timestamp +FROM + {{ this }} + JOIN create_id USING ( + contract_address, + proxy_address + ) +{% endif %} +), +FINAL AS ( + SELECT + contract_address, + proxy_address, + start_block, + _id, + _inserted_timestamp + FROM + heal qualify ROW_NUMBER() over ( + PARTITION BY contract_address, + proxy_address + ORDER BY + start_block ASC + ) = 1 +) +SELECT + f.contract_address, + f.proxy_address, + f.start_block, + f._id, + f._inserted_timestamp, + C.block_number AS created_block, + p.block_number AS proxy_created_block +FROM + FINAL f + JOIN {{ ref('silver_testnet__created_contracts') }} C + ON f.contract_address = C.created_contract_address + JOIN {{ ref('silver_testnet__created_contracts') }} + p + ON f.proxy_address = p.created_contract_address diff --git a/models/silver/abis/silver_testnet__proxies.yml b/models/silver/abis/silver_testnet__proxies.yml new file mode 100644 index 0000000..087094b --- /dev/null +++ b/models/silver/abis/silver_testnet__proxies.yml @@ -0,0 +1,7 @@ +version: 2 +models: + - name: silver_testnet__proxies + tests: + - dbt_utils.unique_combination_of_columns: + combination_of_columns: + - _ID \ No newline at end of file diff --git a/models/silver/abis/silver_testnet__user_verified_abis.sql b/models/silver/abis/silver_testnet__user_verified_abis.sql new file mode 100644 index 0000000..954fe48 --- /dev/null +++ b/models/silver/abis/silver_testnet__user_verified_abis.sql @@ -0,0 +1,550 @@ +{{ config ( + materialized = "incremental", + unique_key = "id", + tags = ['abis'] +) }} + +WITH base AS ( + + SELECT + contract_address, + abi, + PARSE_JSON(abi) AS DATA, + SHA2(PARSE_JSON(abi)) AS abi_hash, + discord_username, + _inserted_timestamp + FROM + {{ source( + "crosschain_public", + "user_abis" + ) }} + WHERE + blockchain = 'berachain-bartio' + AND NOT duplicate_abi + +{% if is_incremental() %} +AND contract_address NOT IN ( + SELECT + contract_address + FROM + {{ this }} +) +AND _inserted_timestamp > ( + SELECT + COALESCE( + MAX( + _inserted_timestamp + ), + '1970-01-01' + ) + FROM + {{ this }} +) +{% endif %} +ORDER BY + _inserted_timestamp ASC +LIMIT + 10 +), flat_event_abi AS ( + SELECT + contract_address, + _inserted_timestamp, + DATA, + VALUE :inputs AS inputs, + VALUE :payable :: BOOLEAN AS payable, + VALUE :stateMutability :: STRING AS stateMutability, + VALUE :type :: STRING AS TYPE, + VALUE :anonymous :: BOOLEAN AS anonymous, + VALUE :name :: STRING AS NAME + FROM + base, + LATERAL FLATTEN ( + input => DATA + ) + WHERE + TYPE = 'event' qualify ROW_NUMBER() over ( + PARTITION BY contract_address, + NAME, + inputs + ORDER BY + LENGTH(inputs) + ) = 1 +), +event_types AS ( + SELECT + contract_address, + _inserted_timestamp, + inputs, + anonymous, + NAME, + ARRAY_AGG( + VALUE :type :: STRING + ) AS event_type + FROM + flat_event_abi, + LATERAL FLATTEN ( + input => inputs + ) + GROUP BY + contract_address, + _inserted_timestamp, + inputs, + anonymous, + NAME +), +apply_event_udfs AS ( + SELECT + contract_address, + NAME AS event_name, + PARSE_JSON( + OBJECT_CONSTRUCT( + 'anonymous', + anonymous, + 'inputs', + inputs, + 'name', + NAME, + 'type', + 'event' + ) :: STRING + ) AS abi, + utils.udf_evm_text_signature(abi) AS simple_event_name, + utils.udf_keccak256(simple_event_name) AS event_signature, + NAME, + inputs, + event_type, + _inserted_timestamp + FROM + event_types +), +final_flat_event_abis AS ( + SELECT + contract_address, + event_name, + abi, + simple_event_name, + event_signature, + NAME, + inputs, + event_type, + _inserted_timestamp + FROM + apply_event_udfs +), +flat_function_abis AS ( + SELECT + contract_address, + DATA, + _inserted_timestamp, + VALUE :inputs AS inputs, + VALUE :outputs AS outputs, + VALUE :payable :: BOOLEAN AS payable, + VALUE :stateMutability :: STRING AS stateMutability, + VALUE :type :: STRING AS TYPE, + VALUE :name :: STRING AS NAME + FROM + base, + LATERAL FLATTEN ( + input => DATA + ) + WHERE + TYPE = 'function' +), +udf_function_abis AS ( + SELECT + *, + PARSE_JSON( + object_construct_keep_null( + 'inputs', + IFNULL( + inputs, + [] + ), + 'outputs', + IFNULL( + outputs, + [] + ), + 'name', + NAME, + 'type', + 'function' + ) :: STRING + ) AS abi, + utils.udf_evm_text_signature(abi) AS simple_function_name, + utils.udf_keccak256(simple_function_name) AS function_signature + FROM + flat_function_abis qualify ROW_NUMBER() over ( + PARTITION BY contract_address, + function_signature + ORDER BY + _inserted_timestamp DESC + ) = 1 +), +flat_inputs AS ( + SELECT + contract_address, + inputs, + NAME, + simple_function_name, + function_signature, + ARRAY_AGG( + VALUE :type :: STRING + ) AS inputs_type + FROM + udf_function_abis, + LATERAL FLATTEN ( + input => inputs + ) + GROUP BY + ALL +), +fill_missing_input_names AS ( + SELECT + contract_address, + NAME, + inputs_type, + simple_function_name, + function_signature, + VALUE :internalType :: STRING AS internalType, + VALUE :type :: STRING AS TYPE, + CASE + WHEN VALUE :name :: STRING = '' THEN CONCAT('input_', ROW_NUMBER() over (PARTITION BY contract_address, function_signature + ORDER BY + INDEX ASC) :: STRING) + ELSE VALUE :name :: STRING + END AS name_fixed, + inputs, + INDEX, + VALUE :components AS components + FROM + flat_inputs, + LATERAL FLATTEN ( + input => inputs + ) +), +final_flat_inputs AS ( + SELECT + contract_address, + NAME, + inputs_type, + simple_function_name, + function_signature, + ARRAY_AGG( + OBJECT_CONSTRUCT( + 'internalType', + internalType, + 'name', + name_fixed, + 'type', + TYPE, + 'components', + components + ) + ) within GROUP ( + ORDER BY + INDEX + ) AS inputs + FROM + fill_missing_input_names + GROUP BY + ALL +), +flat_outputs AS ( + SELECT + contract_address, + outputs, + simple_function_name, + function_signature, + NAME, + ARRAY_AGG( + VALUE :type :: STRING + ) AS outputs_type + FROM + udf_function_abis, + LATERAL FLATTEN ( + input => outputs + ) + GROUP BY + ALL +), +fill_missing_output_names AS ( + SELECT + contract_address, + NAME, + outputs_type, + simple_function_name, + function_signature, + VALUE :internalType :: STRING AS internalType, + VALUE :type :: STRING AS TYPE, + CASE + WHEN VALUE :name :: STRING = '' THEN CONCAT('output_', ROW_NUMBER() over (PARTITION BY contract_address, function_signature + ORDER BY + INDEX ASC) :: STRING) + ELSE VALUE :name :: STRING + END AS name_fixed, + outputs, + INDEX, + VALUE :components AS components + FROM + flat_outputs, + LATERAL FLATTEN ( + input => outputs + ) +), +final_flat_outputs AS ( + SELECT + contract_address, + NAME, + outputs_type, + simple_function_name, + function_signature, + ARRAY_AGG( + OBJECT_CONSTRUCT( + 'internalType', + internalType, + 'name', + name_fixed, + 'type', + TYPE, + 'components', + components + ) + ) within GROUP ( + ORDER BY + INDEX + ) AS outputs + FROM + fill_missing_output_names + GROUP BY + ALL +), +all_contracts AS ( + SELECT + A.contract_address, + A.name AS function_name, + i.inputs, + o.outputs, + i.inputs_type, + o.outputs_type, + A._inserted_timestamp, + A.function_signature, + A.simple_function_name + FROM + udf_function_abis A + LEFT JOIN final_flat_inputs i + ON A.contract_address = i.contract_address + AND A.function_signature = i.function_signature + LEFT JOIN final_flat_outputs o + ON A.contract_address = o.contract_address + AND A.function_signature = o.function_signature +), +apply_function_udfs AS ( + SELECT + contract_address, + function_name, + PARSE_JSON( + object_construct_keep_null( + 'inputs', + IFNULL( + inputs, + [] + ), + 'outputs', + IFNULL( + outputs, + [] + ), + 'name', + function_name, + 'type', + 'function' + ) :: STRING + ) AS abi, + simple_function_name, + function_signature, + inputs, + outputs, + inputs_type, + outputs_type, + _inserted_timestamp + FROM + all_contracts +), +final_function_abis AS ( + SELECT + contract_address, + function_name, + abi, + simple_function_name, + function_signature, + inputs, + outputs, + inputs_type, + outputs_type, + _inserted_timestamp + FROM + apply_function_udfs +), +new_abis AS ( + SELECT + DISTINCT contract_address + FROM + base +), +contracts AS ( + SELECT + contract_address + FROM + {{ ref('silver_testnet__proxies') }} + JOIN new_abis USING (contract_address) +), +proxies AS ( + SELECT + p.proxy_address, + p.contract_address + FROM + {{ ref('silver_testnet__proxies') }} + p + JOIN new_abis n + ON p.proxy_address = n.contract_address +), +final_groupings AS ( + SELECT + b.contract_address AS address, + C.contract_address, + proxy_address, + CASE + WHEN C.contract_address IS NOT NULL + AND proxy_address IS NOT NULL THEN 'contract' + WHEN C.contract_address IS NOT NULL THEN 'contract' + WHEN proxy_address IS NOT NULL THEN 'proxy' + WHEN C.contract_address IS NULL + AND proxy_address IS NULL THEN 'contract' + END AS TYPE, + p.contract_address AS proxy_parent, + CASE + WHEN TYPE = 'contract' THEN address + ELSE proxy_parent + END AS final_address + FROM + base b + LEFT JOIN ( + SELECT + DISTINCT contract_address + FROM + contracts + ) C + ON b.contract_address = C.contract_address + LEFT JOIN ( + SELECT + DISTINCT proxy_address, + contract_address + FROM + proxies + ) p + ON b.contract_address = proxy_address +), +identified_addresses AS ( + SELECT + DISTINCT address AS base_address, + final_address AS contract_address + FROM + final_groupings +), +function_mapping AS ( + SELECT + ia.base_address, + ia.contract_address, + LEFT( + function_signature, + 10 + ) AS function_sig + FROM + identified_addresses ia + JOIN final_function_abis ffa + ON ia.base_address = ffa.contract_address +), +valid_traces AS ( + SELECT + DISTINCT base_address + FROM + ( + SELECT + base_address + FROM + {{ ref('silver_testnet__traces') }} + JOIN function_mapping + ON function_sig = LEFT( + input, + 10 + ) + AND IFF( + TYPE = 'DELEGATECALL', + from_address, + to_address + ) = contract_address + WHERE + block_timestamp > DATEADD('month', -12, SYSDATE()) + LIMIT + 50000) + ), event_mapping AS ( + SELECT + ia.base_address, + ia.contract_address, + event_signature + FROM + identified_addresses ia + JOIN final_flat_event_abis fea + ON ia.base_address = fea.contract_address + ), + valid_logs AS ( + SELECT + DISTINCT base_address + FROM + ( + SELECT + base_address + FROM + {{ ref('silver_testnet__logs') }} + l + JOIN event_mapping ia + ON ia.contract_address = l.contract_address + AND event_signature = topics [0] :: STRING + WHERE + block_timestamp > DATEADD('month', -12, SYSDATE()) + LIMIT + 50000) + ), all_valid_addresses AS ( + SELECT + base_address + FROM + valid_traces + UNION + SELECT + base_address + FROM + valid_logs + ) + SELECT + contract_address, + abi, + discord_username, + _inserted_timestamp, + abi_hash, + CONCAT( + contract_address, + '-', + abi_hash + ) AS id + FROM + base + WHERE + contract_address IN ( + SELECT + base_address + FROM + all_valid_addresses + ) qualify(ROW_NUMBER() over(PARTITION BY contract_address + ORDER BY + _inserted_timestamp DESC)) = 1 diff --git a/models/silver/abis/silver_testnet__user_verified_abis.yml b/models/silver/abis/silver_testnet__user_verified_abis.yml new file mode 100644 index 0000000..e1ca2a9 --- /dev/null +++ b/models/silver/abis/silver_testnet__user_verified_abis.yml @@ -0,0 +1,7 @@ +version: 2 +models: + - name: silver_testnet__user_verified_abis + tests: + - dbt_utils.unique_combination_of_columns: + combination_of_columns: + - ID \ No newline at end of file diff --git a/models/silver/abis/silver_testnet__verified_abis.sql b/models/silver/abis/silver_testnet__verified_abis.sql new file mode 100644 index 0000000..65f95e3 --- /dev/null +++ b/models/silver/abis/silver_testnet__verified_abis.sql @@ -0,0 +1,105 @@ +{{ config( + materialized = 'incremental', + unique_key = "contract_address", + tags = ['abis'] +) }} + +WITH base AS ( + + SELECT + contract_address, + PARSE_JSON( + abi_data :data :result + ) AS DATA, + _inserted_timestamp + FROM + {{ ref('bronze_api_testnet__contract_abis') }} + WHERE + abi_data :data :message :: STRING = 'OK' + +{% if is_incremental() %} +AND _inserted_timestamp >= ( + SELECT + MAX( + _inserted_timestamp + ) + FROM + {{ this }} +) +{% endif %} +), +bscscan_abis AS ( + SELECT + contract_address, + DATA, + _inserted_timestamp, + 'routescan' AS abi_source + FROM + base +), +user_abis AS ( + SELECT + contract_address, + abi, + discord_username, + _inserted_timestamp, + 'user' AS abi_source, + abi_hash + FROM + {{ ref('silver_testnet__user_verified_abis') }} + +{% if is_incremental() %} +WHERE + _inserted_timestamp >= ( + SELECT + COALESCE( + MAX( + _inserted_timestamp + ), + '1970-01-01' + ) + FROM + {{ this }} + WHERE + abi_source = 'user' + ) + AND contract_address NOT IN ( + SELECT + contract_address + FROM + {{ this }} + ) +{% endif %} +), +all_abis AS ( + SELECT + contract_address, + DATA, + _inserted_timestamp, + abi_source, + NULL AS discord_username, + SHA2(DATA) AS abi_hash + FROM + bscscan_abis + UNION + SELECT + contract_address, + PARSE_JSON(abi) AS DATA, + _inserted_timestamp, + 'user' AS abi_source, + discord_username, + abi_hash + FROM + user_abis +) +SELECT + contract_address, + DATA, + _inserted_timestamp, + abi_source, + discord_username, + abi_hash +FROM + all_abis qualify(ROW_NUMBER() over(PARTITION BY contract_address +ORDER BY + _INSERTED_TIMESTAMP DESC)) = 1 diff --git a/models/silver/abis/silver_testnet__verified_abis.yml b/models/silver/abis/silver_testnet__verified_abis.yml new file mode 100644 index 0000000..a89e982 --- /dev/null +++ b/models/silver/abis/silver_testnet__verified_abis.yml @@ -0,0 +1,7 @@ +version: 2 +models: + - name: silver_testnet__verified_abis + tests: + - dbt_utils.unique_combination_of_columns: + combination_of_columns: + - CONTRACT_ADDRESS \ No newline at end of file diff --git a/models/silver/core/silver_testnet__created_contracts.sql b/models/silver/core/silver_testnet__created_contracts.sql new file mode 100644 index 0000000..aaa3e83 --- /dev/null +++ b/models/silver/core/silver_testnet__created_contracts.sql @@ -0,0 +1,45 @@ +{{ config ( + materialized = "incremental", + unique_key = "created_contract_address", + merge_exclude_columns = ["inserted_timestamp"], + cluster_by = "block_timestamp::DATE", + post_hook = "ALTER TABLE {{ this }} ADD SEARCH OPTIMIZATION ON EQUALITY(block_timestamp, tx_hash, created_contract_address, creator_address), SUBSTRING(created_contract_address, creator_address)", + tags = ['non_realtime'] +) }} + +SELECT + block_number, + block_timestamp, + tx_hash, + to_address AS created_contract_address, + from_address AS creator_address, + input AS created_contract_input, + _inserted_timestamp, + {{ dbt_utils.generate_surrogate_key( + ['to_address'] + ) }} AS created_contracts_id, + SYSDATE() AS inserted_timestamp, + SYSDATE() AS modified_timestamp, + '{{ invocation_id }}' AS _invocation_id +FROM + {{ ref('silver_testnet__traces') }} +WHERE + TYPE ILIKE 'create%' + AND to_address IS NOT NULL + AND input IS NOT NULL + AND input != '0x' + AND trace_status = 'SUCCESS' + AND tx_status + +{% if is_incremental() %} +AND _inserted_timestamp >= ( + SELECT + MAX(_inserted_timestamp) - INTERVAL '24 hours' + FROM + {{ this }} +) +{% endif %} + +qualify(ROW_NUMBER() over(PARTITION BY created_contract_address +ORDER BY + block_number DESC, _inserted_timestamp DESC)) = 1 diff --git a/models/silver/core/silver_testnet__created_contracts.yml b/models/silver/core/silver_testnet__created_contracts.yml new file mode 100644 index 0000000..1932669 --- /dev/null +++ b/models/silver/core/silver_testnet__created_contracts.yml @@ -0,0 +1,29 @@ +version: 2 +models: + - name: silver_testnet__created_contracts + tests: + - dbt_utils.unique_combination_of_columns: + combination_of_columns: + - created_contract_address + columns: + - 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 + - TIMESTAMP_LTZ + - name: _INSERTED_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 + - TIMESTAMP_LTZ + \ No newline at end of file diff --git a/models/sources.yml b/models/sources.yml index 2d5ffcb..c5f542e 100644 --- a/models/sources.yml +++ b/models/sources.yml @@ -21,3 +21,9 @@ sources: - name: testnet_transactions - name: testnet_traces - name: testnet_confirm_blocks + - name: testnet_decoded_logs + - name: crosschain_public + database: crosschain + schema: bronze_public + tables: + - name: user_abis diff --git a/models/streamline/decoder/streamline__testnet_complete_decode_logs.sql b/models/streamline/decoder/streamline__testnet_complete_decode_logs.sql new file mode 100644 index 0000000..0b1e554 --- /dev/null +++ b/models/streamline/decoder/streamline__testnet_complete_decode_logs.sql @@ -0,0 +1,33 @@ +-- depends_on: {{ ref('bronze_testnet__decoded_logs') }} +{{ config ( + materialized = "incremental", + unique_key = "_log_id", + cluster_by = "ROUND(block_number, -3)", + merge_update_columns = ["_log_id"], + post_hook = "ALTER TABLE {{ this }} ADD SEARCH OPTIMIZATION on equality(_log_id)", + full_refresh = false, + tags = ['streamline_decoded_logs_complete'] +) }} + +SELECT + block_number, + id AS _log_id, + _inserted_timestamp +FROM + +{% if is_incremental() %} +{{ ref('bronze_testnet__decoded_logs') }} +WHERE + TO_TIMESTAMP_NTZ(_inserted_timestamp) >= ( + SELECT + MAX(_inserted_timestamp) + FROM + {{ this }} + ) +{% else %} + {{ ref('bronze_testnet__fr_decoded_logs') }} +{% endif %} + +qualify(ROW_NUMBER() over (PARTITION BY id +ORDER BY + _inserted_timestamp DESC)) = 1