|
| 1 | +-- create blocks table |
| 2 | +CREATE TABLE IF NOT EXISTS blocks ( |
| 3 | + `chain_id` UInt256, |
| 4 | + `number` UInt256, |
| 5 | + `timestamp` UInt64 CODEC(Delta, ZSTD), |
| 6 | + `hash` FixedString(66), |
| 7 | + `parent_hash` FixedString(66), |
| 8 | + `sha3_uncles` FixedString(66), |
| 9 | + `nonce` FixedString(18), |
| 10 | + `mix_hash` FixedString(66), |
| 11 | + `miner` FixedString(42), |
| 12 | + `state_root` FixedString(66), |
| 13 | + `transactions_root` FixedString(66), |
| 14 | + `receipts_root` FixedString(66), |
| 15 | + `logs_bloom` String, |
| 16 | + `size` UInt64, |
| 17 | + `extra_data` String, |
| 18 | + `difficulty` UInt256, |
| 19 | + `total_difficulty` UInt256, |
| 20 | + `transaction_count` UInt64, |
| 21 | + `gas_limit` UInt256, |
| 22 | + `gas_used` UInt256, |
| 23 | + `withdrawals_root` Nullable(FixedString(66)), |
| 24 | + `base_fee_per_gas` Nullable(UInt64), |
| 25 | + `insert_timestamp` DateTime DEFAULT now(), |
| 26 | + `is_deleted` UInt8 DEFAULT 0, |
| 27 | + INDEX idx_timestamp timestamp TYPE minmax GRANULARITY 1, |
| 28 | + INDEX idx_hash hash TYPE bloom_filter GRANULARITY 1, |
| 29 | +) ENGINE = ReplacingMergeTree(insert_timestamp, is_deleted) |
| 30 | +ORDER BY (chain_id, number) |
| 31 | +PARTITION BY chain_id |
| 32 | +SETTINGS allow_experimental_replacing_merge_with_cleanup = 1; |
| 33 | + |
| 34 | +-- create logs table |
| 35 | +CREATE TABLE IF NOT EXISTS logs ( |
| 36 | + `chain_id` UInt256, |
| 37 | + `block_number` UInt256, |
| 38 | + `block_hash` FixedString(66), |
| 39 | + `block_timestamp` UInt64 CODEC(Delta, ZSTD), |
| 40 | + `transaction_hash` FixedString(66), |
| 41 | + `transaction_index` UInt64, |
| 42 | + `log_index` UInt64, |
| 43 | + `address` FixedString(42), |
| 44 | + `data` String, |
| 45 | + `topic_0` String, |
| 46 | + `topic_1` Nullable(String), |
| 47 | + `topic_2` Nullable(String), |
| 48 | + `topic_3` Nullable(String), |
| 49 | + `insert_timestamp` DateTime DEFAULT now(), |
| 50 | + `is_deleted` UInt8 DEFAULT 0, |
| 51 | + INDEX idx_block_timestamp block_timestamp TYPE minmax GRANULARITY 1, |
| 52 | + INDEX idx_transaction_hash transaction_hash TYPE bloom_filter GRANULARITY 1, |
| 53 | + INDEX idx_block_hash block_hash TYPE bloom_filter GRANULARITY 1, |
| 54 | + INDEX idx_address address TYPE bloom_filter GRANULARITY 1, |
| 55 | + INDEX idx_topic0 topic_0 TYPE bloom_filter GRANULARITY 1, |
| 56 | + INDEX idx_topic1 topic_1 TYPE bloom_filter GRANULARITY 1, |
| 57 | + INDEX idx_topic2 topic_2 TYPE bloom_filter GRANULARITY 1, |
| 58 | + INDEX idx_topic3 topic_3 TYPE bloom_filter GRANULARITY 1, |
| 59 | +) ENGINE = ReplacingMergeTree(insert_timestamp, is_deleted) |
| 60 | +ORDER BY (chain_id, block_number, transaction_hash, log_index) |
| 61 | +PARTITION BY chain_id |
| 62 | +SETTINGS allow_experimental_replacing_merge_with_cleanup = 1; |
| 63 | + |
| 64 | +-- create transactions table |
| 65 | +CREATE TABLE IF NOT EXISTS transactions ( |
| 66 | + `chain_id` UInt256, |
| 67 | + `hash` FixedString(66), |
| 68 | + `nonce` UInt64, |
| 69 | + `block_hash` FixedString(66), |
| 70 | + `block_number` UInt256, |
| 71 | + `block_timestamp` UInt64 CODEC(Delta, ZSTD), |
| 72 | + `transaction_index` UInt64, |
| 73 | + `from_address` FixedString(42), |
| 74 | + `to_address` FixedString(42), |
| 75 | + `value` UInt256, |
| 76 | + `gas` UInt64, |
| 77 | + `gas_price` UInt256, |
| 78 | + `data` String, |
| 79 | + `function_selector` FixedString(10), |
| 80 | + `max_fee_per_gas` UInt128, |
| 81 | + `max_priority_fee_per_gas` UInt128, |
| 82 | + `transaction_type` UInt8, |
| 83 | + `r` UInt256, |
| 84 | + `s` UInt256, |
| 85 | + `v` UInt256, |
| 86 | + `access_list` Nullable(String), |
| 87 | + `contract_address` Nullable(FixedString(42)), |
| 88 | + `gas_used` Nullable(UInt64), |
| 89 | + `cumulative_gas_used` Nullable(UInt64), |
| 90 | + `effective_gas_price` Nullable(UInt256), |
| 91 | + `blob_gas_used` Nullable(UInt64), |
| 92 | + `blob_gas_price` Nullable(UInt256), |
| 93 | + `logs_bloom` Nullable(String), |
| 94 | + `status` Nullable(UInt64), |
| 95 | + `is_deleted` UInt8 DEFAULT 0, |
| 96 | + `insert_timestamp` DateTime DEFAULT now(), |
| 97 | + INDEX idx_block_timestamp block_timestamp TYPE minmax GRANULARITY 1, |
| 98 | + INDEX idx_block_hash block_hash TYPE bloom_filter GRANULARITY 1, |
| 99 | + INDEX idx_hash hash TYPE bloom_filter GRANULARITY 1, |
| 100 | + INDEX idx_from_address from_address TYPE bloom_filter GRANULARITY 1, |
| 101 | + INDEX idx_to_address to_address TYPE bloom_filter GRANULARITY 1, |
| 102 | + INDEX idx_function_selector function_selector TYPE bloom_filter GRANULARITY 1, |
| 103 | +) ENGINE = ReplacingMergeTree(insert_timestamp, is_deleted) |
| 104 | +ORDER BY (chain_id, block_number, hash) |
| 105 | +PARTITION BY chain_id |
| 106 | +SETTINGS allow_experimental_replacing_merge_with_cleanup = 1; |
| 107 | + |
| 108 | +-- create traces table |
| 109 | +CREATE TABLE IF NOT EXISTS traces ( |
| 110 | + `chain_id` UInt256, |
| 111 | + `block_number` UInt256, |
| 112 | + `block_hash` FixedString(66), |
| 113 | + `block_timestamp` UInt64 CODEC(Delta, ZSTD), |
| 114 | + `transaction_hash` FixedString(66), |
| 115 | + `transaction_index` UInt64, |
| 116 | + `subtraces` Int64, |
| 117 | + `trace_address` Array(Int64), |
| 118 | + `type` LowCardinality(String), |
| 119 | + `call_type` LowCardinality(String), |
| 120 | + `error` Nullable(String), |
| 121 | + `from_address` FixedString(42), |
| 122 | + `to_address` FixedString(42), |
| 123 | + `gas` UInt64, |
| 124 | + `gas_used` UInt64, |
| 125 | + `input` String, |
| 126 | + `output` Nullable(String), |
| 127 | + `value` UInt256, |
| 128 | + `author` Nullable(FixedString(42)), |
| 129 | + `reward_type` LowCardinality(Nullable(String)), |
| 130 | + `refund_address` Nullable(FixedString(42)), |
| 131 | + `is_deleted` UInt8 DEFAULT 0, |
| 132 | + `insert_timestamp` DateTime DEFAULT now(), |
| 133 | + INDEX idx_block_timestamp block_timestamp TYPE minmax GRANULARITY 1, |
| 134 | + INDEX idx_block_hash block_hash TYPE bloom_filter GRANULARITY 1, |
| 135 | + INDEX idx_transaction_hash transaction_hash TYPE bloom_filter GRANULARITY 1, |
| 136 | + INDEX idx_from_address from_address TYPE bloom_filter GRANULARITY 1, |
| 137 | + INDEX idx_to_address to_address TYPE bloom_filter GRANULARITY 1, |
| 138 | + INDEX idx_type type TYPE bloom_filter GRANULARITY 1, |
| 139 | +) ENGINE = ReplacingMergeTree(insert_timestamp, is_deleted) |
| 140 | +ORDER BY (chain_id, block_number, transaction_hash, trace_address) |
| 141 | +PARTITION BY chain_id |
| 142 | +SETTINGS allow_experimental_replacing_merge_with_cleanup = 1; |
0 commit comments