-
Notifications
You must be signed in to change notification settings - Fork 0
/
schema.sql.example
200 lines (169 loc) · 6.11 KB
/
schema.sql.example
1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
18
19
20
21
22
23
24
25
26
27
28
29
30
31
32
33
34
35
36
37
38
39
40
41
42
43
44
45
46
47
48
49
50
51
52
53
54
55
56
57
58
59
60
61
62
63
64
65
66
67
68
69
70
71
72
73
74
75
76
77
78
79
80
81
82
83
84
85
86
87
88
89
90
91
92
93
94
95
96
97
98
99
100
101
102
103
104
105
106
107
108
109
110
111
112
113
114
115
116
117
118
119
120
121
122
123
124
125
126
127
128
129
130
131
132
133
134
135
136
137
138
139
140
141
142
143
144
145
146
147
148
149
150
151
152
153
154
155
156
157
158
159
160
161
162
163
164
165
166
167
168
169
170
171
172
173
174
175
176
177
178
179
180
181
182
183
184
185
186
187
188
189
190
191
192
193
194
195
196
197
198
199
200
-------------------------------------------------
-- Meta tables to store Substreams information --
-------------------------------------------------
CREATE TABLE IF NOT EXISTS cursors ON CLUSTER cluster_name
(
id String,
cursor String,
block_num Int64,
block_id String
)
ENGINE = ReplicatedReplacingMergeTree()
PRIMARY KEY (id)
ORDER BY (id);
-------------------------------------------------
-- -- Table for all balance changes event --
-------------------------------------------------
CREATE TABLE IF NOT EXISTS balance_changes ON CLUSTER cluster_name (
"id" String,
timestamp DateTime64(3, 'UTC'),
contract FixedString(40),
owner FixedString(40),
amount UInt256,
old_balance UInt256,
new_balance UInt256,
transaction_id FixedString(64),
block_num UInt32(),
change_type Int32
)
ENGINE = ReplicatedMergeTree PRIMARY KEY ("id")
ORDER BY (id,timestamp, block_num);
------------------------------------------------------------------------------
-- -- MV for historical balance changes event order by contract address --
------------------------------------------------------------------------------
CREATE MATERIALIZED VIEW balance_changes_contract_historical_mv ON CLUSTER cluster_name
ENGINE = ReplicatedReplacingMergeTree()
ORDER BY (contract, owner,block_num)
POPULATE
AS SELECT * FROM balance_changes;
------------------------------------------------------------------------------
-- -- MV for historical balance changes event order by account address --
------------------------------------------------------------------------------
CREATE MATERIALIZED VIEW balance_changes_account_historical_mv ON CLUSTER cluster_name
ENGINE = ReplicatedReplacingMergeTree()
ORDER BY (owner, contract,block_num)
POPULATE
AS SELECT * FROM balance_changes;
-------------------------------------------
-- -- MV for latest token_holders --
-------------------------------------------
CREATE TABLE IF NOT EXISTS token_holders ON CLUSTER cluster_name
(
account FixedString(40),
contract String,
amount UInt256,
block_num UInt32(),
timestamp DateTime64(3, 'UTC'),
tx_id FixedString(64)
)
ENGINE = ReplicatedReplacingMergeTree(block_num)
PRIMARY KEY (contract,account)
ORDER BY (contract, account);
CREATE MATERIALIZED VIEW token_holders_mv ON CLUSTER cluster_name
TO token_holders
AS
SELECT owner as account,
contract,
new_balance as amount,
block_num,
timestamp,
transaction_id as tx_id
FROM balance_changes;
-------------------------------------------
-- MV for account balances --
-------------------------------------------
CREATE TABLE IF NOT EXISTS account_balances ON CLUSTER cluster_name
(
account FixedString(40),
contract String,
amount UInt256,
block_num UInt32(),
timestamp DateTime64(3, 'UTC'),
tx_id FixedString(64)
)
ENGINE = ReplicatedReplacingMergeTree(block_num)
PRIMARY KEY (account,contract)
ORDER BY (account,contract);
CREATE MATERIALIZED VIEW account_balances_mv ON CLUSTER cluster_name
TO account_balances
AS
SELECT owner as account,
contract,
amount,
block_num,
timestamp,
transaction_id as tx_id
FROM balance_changes;
-------------------------------------------------
-- Table for all token information --
-------------------------------------------------
CREATE TABLE IF NOT EXISTS contracts ON CLUSTER cluster_name (
contract FixedString(40),
name String,
symbol String,
decimals UInt64,
block_num UInt32(),
timestamp DateTime64(3, 'UTC'),
)
ENGINE = ReplicatedReplacingMergeTree PRIMARY KEY ("contract")
ORDER BY (contract);
-------------------------------------------------
-- Table for token supply --
-------------------------------------------------
CREATE TABLE IF NOT EXISTS supply ON CLUSTER cluster_name (
contract FixedString(40),
supply UInt256,
block_num UInt32(),
timestamp DateTime64(3, 'UTC'),
)
ENGINE = ReplicatedReplacingMergeTree()
ORDER BY (contract,block_num);
-------------------------------------------------
-- MV for token supply order by contract address --
-------------------------------------------------
CREATE MATERIALIZED VIEW mv_supply_contract ON CLUSTER cluster_name
ENGINE = ReplicatedReplacingMergeTree()
ORDER BY (contract,block_num)
POPULATE
AS SELECT * FROM supply;
-------------------------------------------------
-- table for all transfers events --
-------------------------------------------------
CREATE TABLE IF NOT EXISTS transfers ON CLUSTER cluster_name (
id String,
contract FixedString(40),
`from` String,
`to` String,
value String,
tx_id String,
action_index UInt32,
block_num UInt32,
timestamp DateTime64(3, 'UTC')
)
ENGINE = ReplicatedMergeTree
PRIMARY KEY (id)
ORDER BY (id, tx_id, block_num, timestamp);
-------------------------------------------------
-- MV for historical transfers events by contract address --
-------------------------------------------------
CREATE MATERIALIZED VIEW transfers_contract_historical_mv ON CLUSTER cluster_name
ENGINE = ReplicatedReplacingMergeTree()
ORDER BY (contract, `from`,`to`,block_num)
POPULATE
AS SELECT * FROM transfers;
-------------------------------------------------
-- MV for historical transfers events by from address --
-------------------------------------------------
CREATE MATERIALIZED VIEW transfers_from_historical_mv ON CLUSTER cluster_name
ENGINE = ReplicatedReplacingMergeTree()
ORDER BY (`from`, contract,block_num)
POPULATE
AS SELECT * FROM transfers;
-------------------------------------------------
-- MV for historical transfers events by to address --
-------------------------------------------------
CREATE MATERIALIZED VIEW transfers_to_historical_mv ON CLUSTER cluster_name
ENGINE = ReplicatedReplacingMergeTree()
ORDER BY (`to`, contract,block_num)
POPULATE
AS SELECT * FROM transfers;