From 137a29a108c263594dbab04a15948447164f54f7 Mon Sep 17 00:00:00 2001 From: iljagrabar14 Date: Mon, 29 Jul 2024 11:43:23 +0200 Subject: [PATCH] Init tables and writers for neutron --- migrations/clickhouse/000002_message.sql | 30 ++++ .../000003_dex_message_event_tick_update.sql | 130 ++++++++++++++++++ migrations/clickhouse/000004_wasm_events.sql | 53 +++++++ .../clickhouse/000005_debs_and_creds.sql | 60 ++++++++ 4 files changed, 273 insertions(+) create mode 100644 migrations/clickhouse/000002_message.sql create mode 100644 migrations/clickhouse/000003_dex_message_event_tick_update.sql create mode 100644 migrations/clickhouse/000004_wasm_events.sql create mode 100644 migrations/clickhouse/000005_debs_and_creds.sql diff --git a/migrations/clickhouse/000002_message.sql b/migrations/clickhouse/000002_message.sql new file mode 100644 index 0000000..d75fdb3 --- /dev/null +++ b/migrations/clickhouse/000002_message.sql @@ -0,0 +1,30 @@ +CREATE TABLE spacebox.message +( + `timestamp` DateTime, + `height` Int64, + `txhash` String, + `type` String, + `signer` String, + `message` String +) +ENGINE = MergeTree +ORDER BY (timestamp, + height, + txhash, + type, + signer) + + +CREATE MATERIALIZED VIEW spacebox.message_writer TO spacebox.message AS +SELECT + timestamp, + height, + txhash, + arrayJoin(JSONExtractArrayRaw(JSONExtractString(tx, + 'body', + 'messages'))) AS message, + JSONExtractString(msg, + '@type') AS type, + signer +FROM spacebox.raw_transaction; + diff --git a/migrations/clickhouse/000003_dex_message_event_tick_update.sql b/migrations/clickhouse/000003_dex_message_event_tick_update.sql new file mode 100644 index 0000000..49b1430 --- /dev/null +++ b/migrations/clickhouse/000003_dex_message_event_tick_update.sql @@ -0,0 +1,130 @@ +CREATE TABLE spacebox.dex_message_event_tick_update +( + `timestamp` DateTime, + `height` Int64, + `txhash` String, + `attributes` String, + `signer` String, + `TokenZero` String, + `TokenOne` String, + `TokenIn` String, + `TickIndex` Int32, + `TrancheKey` String, + `Fee` UInt16, + `Reserves` Int256 +) +ENGINE = MergeTree +ORDER BY (timestamp, + height, + txhash, + signer, + TokenZero, + TokenOne, + TokenIn, + TickIndex, + TrancheKey) +SETTINGS index_granularity = 8192 + + +CREATE MATERIALIZED VIEW spacebox.dex_message_event_tick_update_writer TO spacebox.dex_message_event_tick_update +( + `timestamp` DateTime, + `height` Int64, + `txhash` String, + `attributes` String, + `signer` String, + `TokenZero` String, + `TokenOne` String, + `TokenIn` String, + `TickIndex` Int32, + `TrancheKey` String, + `Fee` UInt16, + `Reserves` UInt256 +) AS +WITH + raw_tx AS + ( + SELECT + timestamp, + height, + txhash, + events, + signer + FROM spacebox.raw_transaction + WHERE code = 0 + ), + raw_tx_event AS + ( + SELECT + timestamp, + height, + txhash, + type, + attributes, + signer + FROM raw_tx + ARRAY JOIN + arrayMap(x -> JSONExtractString(x, + 'type'), + JSONExtractArrayRaw(events)) AS type, + arrayMap(x -> JSONExtractString(x, + 'attributes'), + JSONExtractArrayRaw(events)) AS attributes + ), + dex_message_event AS + ( + SELECT + timestamp, + height, + txhash, + type, + attributes, + JSONExtractString(arrayFilter(x -> (JSONExtractString(x, + 'key') = 'action'), + JSONExtractArrayRaw(attributes))[1], + 'value') AS action, + signer + FROM raw_tx_event + WHERE JSONExtractString(arrayFilter(x -> (JSONExtractString(x, + 'key') = 'module'), + JSONExtractArrayRaw(attributes))[1], + 'value') = 'dex' + ) +SELECT + timestamp, + height, + txhash, + attributes, + signer, + JSONExtractString(arrayFilter(x -> (JSONExtractString(x, + 'key') = 'TokenZero'), + JSONExtractArrayRaw(attributes))[1], + 'value') AS TokenZero, + JSONExtractString(arrayFilter(x -> (JSONExtractString(x, + 'key') = 'TokenOne'), + JSONExtractArrayRaw(attributes))[1], + 'value') AS TokenOne, + JSONExtractString(arrayFilter(x -> (JSONExtractString(x, + 'key') = 'TokenIn'), + JSONExtractArrayRaw(attributes))[1], + 'value') AS TokenIn, + toInt32(JSONExtractString(arrayFilter(x -> (JSONExtractString(x, + 'key') = 'TickIndex'), + JSONExtractArrayRaw(attributes))[1], + 'value')) AS TickIndex, + JSONExtractString(arrayFilter(x -> (JSONExtractString(x, + 'key') = 'TrancheKey'), + JSONExtractArrayRaw(attributes))[1], + 'value') AS TrancheKey, + if(empty(TrancheKey) = 1, + toUInt16OrZero(JSONExtractString(arrayFilter(x -> (JSONExtractString(x, + 'key') = 'Fee'), + JSONExtractArrayRaw(attributes))[1], + 'value')), + 0) AS Fee, + toUInt256(JSONExtractString(arrayFilter(x -> (JSONExtractString(x, + 'key') = 'Reserves'), + JSONExtractArrayRaw(attributes))[1], + 'value')) AS Reserves +FROM dex_message_event +WHERE action = 'TickUpdate' diff --git a/migrations/clickhouse/000004_wasm_events.sql b/migrations/clickhouse/000004_wasm_events.sql new file mode 100644 index 0000000..436852e --- /dev/null +++ b/migrations/clickhouse/000004_wasm_events.sql @@ -0,0 +1,53 @@ +CREATE TABLE spacebox.wasm_events +( + `timestamp` DateTime, + `height` Int64, + `contract_address` String, + `action` String, + `attributes` String, + `signer` String, + `txhash` String +) +ENGINE = MergeTree +ORDER BY (height, contract_address, action, signer, txhash) + + +CREATE MATERIALIZED VIEW spacebox.wasm_events_writer TO spacebox.wasm_events +( + `timestamp` DateTime, + `height` Int64, + `txhash` String, + `signer` String, + `contract_address` String, + `action` String, + `attributes` String +) AS +WITH events AS + ( + SELECT + timestamp, + height, + txhash, + signer, + JSONExtractString(arrayJoin(JSONExtractArrayRaw(events)), + 'type') AS type, + JSONExtractString(arrayJoin(JSONExtractArrayRaw(events)), + 'attributes') AS attributes + FROM spacebox.raw_transaction + ) +SELECT + timestamp, + height, + txhash, + signer, + JSONExtractString(arrayFilter(x -> (JSONExtractString(x, + 'key') = '_contract_address'), + JSONExtractArrayRaw(attributes))[1], + 'value') AS contract_address, + JSONExtractString(arrayFilter(x -> (JSONExtractString(x, + 'key') = 'action'), + JSONExtractArrayRaw(attributes))[1], + 'value') AS action, + attributes +FROM events +WHERE type = 'wasm' \ No newline at end of file diff --git a/migrations/clickhouse/000005_debs_and_creds.sql b/migrations/clickhouse/000005_debs_and_creds.sql new file mode 100644 index 0000000..940fd05 --- /dev/null +++ b/migrations/clickhouse/000005_debs_and_creds.sql @@ -0,0 +1,60 @@ +CREATE TABLE spacebox.debs_and_creds +( + `height` Int64, + `type` String, + `address` String, + `coins` String, + `amount` Int64, + `denom` String +) +ENGINE = MergeTree +ORDER BY (height, + address, + denom) + + +CREATE MATERIALIZED VIEW spacebox.debs_and_creds_writer TO spacebox.debs_and_creds +( + `height` Int64, + `type` String, + `address` String, + `coins` String, + `amount` Int64, + `denom` String +) AS +WITH txs_events AS + ( + SELECT + height, JSONExtractString(arrayJoin(JSONExtractArrayRaw(JSONExtractString(arrayJoin(JSONExtractArrayRaw(JSONExtractString(txs_results))), + 'events'))), + 'type') AS type, JSONExtractString(arrayJoin(JSONExtractArrayRaw(JSONExtractString(arrayJoin(JSONExtractArrayRaw(JSONExtractString(txs_results))), + 'events'))), + 'attributes') AS attributes + FROM spacebox.raw_block_results + ) +SELECT + height, + type, + if(type = 'coin_spent', + JSONExtractString(arrayFilter(x -> (JSONExtractString(x, + 'key') = 'spender'), + JSONExtractArrayRaw(attributes))[1], + 'value'), + JSONExtractString(arrayFilter(x -> (JSONExtractString(x, + 'key') = 'receiver'), + JSONExtractArrayRaw(attributes))[1], + 'value')) AS address, + arrayJoin(splitByChar(',', + JSONExtractString(arrayFilter(x -> (JSONExtractString(x, + 'key') = 'amount'), + JSONExtractArrayRaw(attributes))[1], + 'value'))) AS coins, + if(type = 'coin_spent', + -toInt64OrZero(extract(coins, + '^(\\d+)')), + toInt64OrZero(extract(coins, + '^(\\d+)'))) AS amount, + extract(coins, + '^\\d+(.*)') AS denom +FROM txs_events +WHERE (type = 'coin_received') OR (type = 'coin_spent');