Skip to content

Commit

Permalink
Merge pull request #16 from pinax-network/refactor/primary-key
Browse files Browse the repository at this point in the history
Add Clickhouse Projections to query by block_date & block_number
  • Loading branch information
DenisCarriere authored Sep 18, 2024
2 parents b0cafb5 + e805dd6 commit 99d8116
Showing 1 changed file with 144 additions and 81 deletions.
225 changes: 144 additions & 81 deletions blocks/antelope/schema.sql
Original file line number Diff line number Diff line change
Expand Up @@ -81,6 +81,87 @@ CREATE TABLE IF NOT EXISTS transactions
ORDER BY (hash)
COMMENT 'Antelope transactions';

CREATE TABLE IF NOT EXISTS actions
(
-- clock --
block_time DateTime64(3, 'UTC'),
block_number UInt64,
block_hash String COMMENT 'Hash',
block_date Date,

-- transaction --
tx_hash String COMMENT 'Hash',
tx_success Bool,

-- receipt --
abi_sequence UInt64,
code_sequence UInt64,
digest String,
global_sequence UInt64,
receipt_receiver String COMMENT 'Address',
recv_sequence UInt64,

-- action --
account String COMMENT 'Address',
name String COMMENT 'Address',
json_data String COMMENT 'JSON',
raw_data String COMMENT 'Hex',

-- trace --
`index` UInt32 COMMENT 'Execution Index',
action_ordinal UInt32 COMMENT 'Action Ordinal',
receiver String,
context_free Bool,
elapsed Int64,
console String,
raw_return_value String,
json_return_value String,
creator_action_ordinal UInt32,
closest_unnotified_ancestor_action_ordinal UInt32,

-- block roots --
action_mroot String,
)
ENGINE = ReplacingMergeTree()
PRIMARY KEY (tx_hash, `index`)
ORDER BY (tx_hash, `index`)
COMMENT 'Antelope actions';

CREATE TABLE IF NOT EXISTS db_ops
(
-- clock --
block_time DateTime64(3, 'UTC'),
block_number UInt64,
block_hash String,
block_date Date,

-- transaction --
tx_hash String,
tx_success Bool,

-- action --
action_index UInt32,

-- database operation --
`index` UInt32,
operation LowCardinality(String) COMMENT 'Operation',
operation_code UInt8,
code String,
scope String,
table_name String,
primary_key String,
old_payer String,
new_payer String,
old_data String,
new_data String,
old_data_json String,
new_data_json String,
)
ENGINE = ReplacingMergeTree()
PRIMARY KEY (tx_hash, `index`)
ORDER BY (tx_hash, `index`)
COMMENT 'Antelope database operations';

CREATE TABLE IF NOT EXISTS feature_ops
(
-- clock --
Expand Down Expand Up @@ -273,87 +354,6 @@ CREATE TABLE IF NOT EXISTS ram_ops
ORDER BY (tx_hash, action_index, unique_key)
COMMENT 'Antelope RAM operations';

CREATE TABLE IF NOT EXISTS actions
(
-- clock --
block_time DateTime64(3, 'UTC'),
block_number UInt64,
block_hash String COMMENT 'Hash',
block_date Date,

-- transaction --
tx_hash String COMMENT 'Hash',
tx_success Bool,

-- receipt --
abi_sequence UInt64,
code_sequence UInt64,
digest String,
global_sequence UInt64,
receipt_receiver String COMMENT 'Address',
recv_sequence UInt64,

-- action --
account String COMMENT 'Address',
name String COMMENT 'Address',
json_data String COMMENT 'JSON',
raw_data String COMMENT 'Hex',

-- trace --
`index` UInt32 COMMENT 'Execution Index',
action_ordinal UInt32 COMMENT 'Action Ordinal',
receiver String,
context_free Bool,
elapsed Int64,
console String,
raw_return_value String,
json_return_value String,
creator_action_ordinal UInt32,
closest_unnotified_ancestor_action_ordinal UInt32,

-- block roots --
action_mroot String,
)
ENGINE = ReplacingMergeTree()
PRIMARY KEY (tx_hash, `index`)
ORDER BY (tx_hash, `index`)
COMMENT 'Antelope actions';

CREATE TABLE IF NOT EXISTS db_ops
(
-- clock --
block_time DateTime64(3, 'UTC'),
block_number UInt64,
block_hash String,
block_date Date,

-- transaction --
tx_hash String,
tx_success Bool,

-- action --
action_index UInt32,

-- database operation --
`index` UInt32,
operation LowCardinality(String) COMMENT 'Operation',
operation_code UInt8,
code String,
scope String,
table_name String,
primary_key String,
old_payer String,
new_payer String,
old_data String,
new_data String,
old_data_json String,
new_data_json String,
)
ENGINE = ReplacingMergeTree()
PRIMARY KEY (tx_hash, `index`)
ORDER BY (tx_hash, `index`)
COMMENT 'Antelope database operations';

CREATE TABLE IF NOT EXISTS authorizations
(
-- clock --
Expand Down Expand Up @@ -450,3 +450,66 @@ CREATE TABLE IF NOT EXISTS creation_tree
ORDER BY (tx_hash, creator_action_index, execution_action_index)
COMMENT 'Antelope creation tree';

-- Projections --
-- https://clickhouse.com/docs/en/sql-reference/statements/alter/projection --
ALTER TABLE blocks ADD PROJECTION IF NOT EXISTS blocks_by_block_number (
SELECT * ORDER BY date, number
);
ALTER TABLE transactions ADD PROJECTION IF NOT EXISTS transactions_by_block_number (
SELECT * ORDER BY block_date, block_number
);
ALTER TABLE actions ADD PROJECTION IF NOT EXISTS actions_by_block_number (
SELECT * ORDER BY block_date, block_number
);
ALTER TABLE db_ops ADD PROJECTION IF NOT EXISTS db_ops_by_block_number (
SELECT * ORDER BY block_date, block_number
);
ALTER TABLE feature_ops ADD PROJECTION IF NOT EXISTS feature_ops_by_block_number (
SELECT * ORDER BY block_date, block_number
);
ALTER TABLE perm_ops ADD PROJECTION IF NOT EXISTS perm_ops_by_block_number (
SELECT * ORDER BY block_date, block_number
);
ALTER TABLE table_ops ADD PROJECTION IF NOT EXISTS table_ops_by_block_number (
SELECT * ORDER BY block_date, block_number
);
ALTER TABLE accounts ADD PROJECTION IF NOT EXISTS accounts_by_block_number (
SELECT * ORDER BY block_date, block_number
);
ALTER TABLE keys ADD PROJECTION IF NOT EXISTS keys_by_block_number (
SELECT * ORDER BY block_date, block_number
);
ALTER TABLE waits ADD PROJECTION IF NOT EXISTS waits_by_block_number (
SELECT * ORDER BY block_date, block_number
);
ALTER TABLE ram_ops ADD PROJECTION IF NOT EXISTS ram_ops_by_block_number (
SELECT * ORDER BY block_date, block_number
);
ALTER TABLE authorizations ADD PROJECTION IF NOT EXISTS authorizations_by_block_number (
SELECT * ORDER BY block_date, block_number
);
ALTER TABLE auth_sequences ADD PROJECTION IF NOT EXISTS auth_sequences_by_block_number (
SELECT * ORDER BY block_date, block_number
);
ALTER TABLE account_ram_deltas ADD PROJECTION IF NOT EXISTS account_ram_deltas_by_block_number (
SELECT * ORDER BY block_date, block_number
);
ALTER TABLE creation_tree ADD PROJECTION IF NOT EXISTS creation_tree_by_block_number (
SELECT * ORDER BY block_date, block_number
);

ALTER TABLE blocks MATERIALIZE PROJECTION blocks_by_block_number;
ALTER TABLE transactions MATERIALIZE PROJECTION transactions_by_block_number;
ALTER TABLE feature_ops MATERIALIZE PROJECTION feature_ops_by_block_number;
ALTER TABLE perm_ops MATERIALIZE PROJECTION perm_ops_by_block_number;
ALTER TABLE table_ops MATERIALIZE PROJECTION table_ops_by_block_number;
ALTER TABLE accounts MATERIALIZE PROJECTION accounts_by_block_number;
ALTER TABLE keys MATERIALIZE PROJECTION keys_by_block_number;
ALTER TABLE waits MATERIALIZE PROJECTION waits_by_block_number;
ALTER TABLE ram_ops MATERIALIZE PROJECTION ram_ops_by_block_number;
ALTER TABLE actions MATERIALIZE PROJECTION actions_by_block_number;
ALTER TABLE db_ops MATERIALIZE PROJECTION db_ops_by_block_number;
ALTER TABLE authorizations MATERIALIZE PROJECTION authorizations_by_block_number;
ALTER TABLE auth_sequences MATERIALIZE PROJECTION auth_sequences_by_block_number;
ALTER TABLE account_ram_deltas MATERIALIZE PROJECTION account_ram_deltas_by_block_number;
ALTER TABLE creation_tree MATERIALIZE PROJECTION creation_tree_by_block_number;

0 comments on commit 99d8116

Please sign in to comment.