forked from chimmykk/NAMADA-DONOR-DROP
-
Notifications
You must be signed in to change notification settings - Fork 1
/
Copy pathinit.sql
464 lines (391 loc) · 13.4 KB
/
init.sql
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
201
202
203
204
205
206
207
208
209
210
211
212
213
214
215
216
217
218
219
220
221
222
223
224
225
226
227
228
229
230
231
232
233
234
235
236
237
238
239
240
241
242
243
244
245
246
247
248
249
250
251
252
253
254
255
256
257
258
259
260
261
262
263
264
265
266
267
268
269
270
271
272
273
274
275
276
277
278
279
280
281
282
283
284
285
286
287
288
289
290
291
292
293
294
295
296
297
298
299
300
301
302
303
304
305
306
307
308
309
310
311
312
313
314
315
316
317
318
319
320
321
322
323
324
325
326
327
328
329
330
331
332
333
334
335
336
337
338
339
340
341
342
343
344
345
346
347
348
349
350
351
352
353
354
355
356
357
358
359
360
361
362
363
364
365
366
367
368
369
370
371
372
373
374
375
376
377
378
379
380
381
382
383
384
385
386
387
388
389
390
391
392
393
394
395
396
397
398
399
400
401
402
403
404
405
406
407
408
409
410
411
412
413
414
415
416
417
418
419
420
421
422
423
424
425
426
427
428
429
430
431
432
433
434
435
436
437
438
439
440
441
442
443
444
445
446
447
448
449
450
451
452
453
454
455
456
457
458
459
460
461
462
463
464
CREATE TABLE IF NOT EXISTS donations (
id SERIAL PRIMARY KEY,
transaction_hash VARCHAR(66) UNIQUE NOT NULL,
from_address VARCHAR(42) NOT NULL,
amount_eth DECIMAL(20,18) NOT NULL,
namada_key VARCHAR(66) NOT NULL,
input_message VARCHAR,
message VARCHAR(100) NULL,
timestamp TIMESTAMPTZ NOT NULL,
created_at TIMESTAMPTZ DEFAULT CURRENT_TIMESTAMP,
block_number BIGINT NOT NULL,
tx_index INTEGER NOT NULL
);
-- Add index for timestamp-based queries
CREATE INDEX idx_donations_timestamp ON donations(timestamp);
CREATE INDEX idx_donations_address_timestamp ON donations(from_address, timestamp, amount_eth);
CREATE TABLE IF NOT EXISTS donations_finalized (
id SERIAL PRIMARY KEY,
transaction_hash VARCHAR(66) UNIQUE NOT NULL,
from_address VARCHAR(42) NOT NULL,
amount_eth DECIMAL(20,18) NOT NULL,
namada_key VARCHAR(66) NOT NULL,
input_message VARCHAR,
message VARCHAR(100) NULL,
timestamp TIMESTAMPTZ NOT NULL,
created_at TIMESTAMPTZ DEFAULT CURRENT_TIMESTAMP,
block_number BIGINT NOT NULL,
tx_index INTEGER NOT NULL
);
-- Add index for timestamp-based queries
CREATE INDEX idx_donations_finalized_timestamp ON donations_finalized(timestamp);
CREATE INDEX idx_donations_finalized_address_timestamp ON donations_finalized(from_address, timestamp, amount_eth);
CREATE TABLE IF NOT EXISTS scraped_blocks (
id SERIAL PRIMARY KEY,
block_number BIGINT UNIQUE NOT NULL,
scraped_at TIMESTAMPTZ DEFAULT CURRENT_TIMESTAMP,
transactions_found INTEGER DEFAULT 0
);
-- Create an index for faster block number lookups
CREATE INDEX idx_block_number ON scraped_blocks(block_number);
CREATE TABLE IF NOT EXISTS scraped_blocks_finalized (
id SERIAL PRIMARY KEY,
block_number BIGINT UNIQUE NOT NULL,
scraped_at TIMESTAMPTZ DEFAULT CURRENT_TIMESTAMP,
transactions_found INTEGER DEFAULT 0
);
-- Create an index for faster block number lookups
CREATE INDEX idx_block_number_finalized ON scraped_blocks_finalized(block_number);
-- params table (TODO: useful for the next iteration, see issue #15)
-- CREATE TABLE IF NOT EXISTS params
-- (
-- global_eth_cap DECIMAL DEFAULT 30,
-- individual_eth_minimum DECIMAL DEFAULT 0.03,
-- individual_eth_cap DECIMAL DEFAULT 0.3,
-- reward_nam INTEGER DEFAULT 1000000,
-- start_date TIMESTAMPTZ NOT NULL,
-- end_date TIMESTAMPTZ NOT NULL
-- );
CREATE TABLE IF NOT EXISTS temporary_messages (
from_address VARCHAR(42) PRIMARY KEY,
message VARCHAR(100) NOT NULL,
created_at TIMESTAMPTZ DEFAULT CURRENT_TIMESTAMP
);
-- Create the function to delete messages older than 10 minutes
CREATE OR REPLACE FUNCTION delete_old_messages()
RETURNS TRIGGER AS $$
BEGIN
DELETE FROM temporary_messages
WHERE created_at < NOW() - INTERVAL '10 minutes';
RETURN NULL; -- No row needs to be returned
END;
$$ LANGUAGE plpgsql;
-- Create the trigger to call the function after insert or update
CREATE OR REPLACE TRIGGER expire_messages
AFTER INSERT OR UPDATE ON temporary_messages
FOR EACH ROW
EXECUTE FUNCTION delete_old_messages();
-- Views
DROP VIEW IF EXISTS combined_donations;
DROP VIEW IF EXISTS the_full_table;
DROP VIEW IF EXISTS the_finalized_transactions_full_table;
DROP VIEW IF EXISTS address_totals;
DROP VIEW IF EXISTS address_totals_finalized;
DROP VIEW IF EXISTS eligible_addresses;
DROP VIEW IF EXISTS eligible_addresses_finalized;
DROP VIEW IF EXISTS donation_stats;
DROP VIEW IF EXISTS donation_stats_finalized;
CREATE VIEW combined_donations AS
WITH temp AS (
SELECT COALESCE(MAX(block_number), 0) as last_finalized_block
FROM scraped_blocks_finalized
)
SELECT *
FROM donations_finalized
WHERE block_number <= (SELECT last_finalized_block FROM temp)
UNION
SELECT *
FROM donations
WHERE block_number > (SELECT last_finalized_block FROM temp);
CREATE VIEW the_full_table AS
-- query name totally new
WITH running_totals AS (
-- Calculate running totals per address in transaction order
SELECT
id,
from_address,
amount_eth,
block_number,
tx_index,
SUM(amount_eth) OVER (
PARTITION BY from_address
ORDER BY block_number, tx_index
ROWS BETWEEN UNBOUNDED PRECEDING AND CURRENT ROW
) as address_running_total,
COALESCE(SUM(amount_eth) OVER (
PARTITION BY from_address
ORDER BY block_number, tx_index
ROWS BETWEEN UNBOUNDED PRECEDING AND 1 PRECEDING
), 0) as preceding_running_total
FROM combined_donations
),
eligible_amounts AS (
--WITH the_big_temporary_table AS (
--we gon do some smart stuff here
SELECT
id,
from_address,
block_number,
tx_index,
amount_eth,
address_running_total,
preceding_running_total,
--these are eligible amount contributions for this particular transaction (not cumulative, unless previous donations have been too low..)
CASE
--not enough donations yet
WHEN address_running_total < 0.03 THEN 0
--already met the cap before this donation
WHEN preceding_running_total > 0.3 THEN 0
--previous donations under individual cap (if we are here in the struct, we have gone over cap already) contribution here will be either full address running total, or 0.3 if we go over the cap (ie running total > 0.3)
WHEN preceding_running_total < 0.03 THEN
LEAST(address_running_total, 0.3)
--if this transaction brought us over individual cap (and preceding cases excluded)
WHEN address_running_total > 0.3 THEN
(0.3 - preceding_running_total)
--all other cases
ELSE amount_eth
END
AS eligible_amount
FROM running_totals
ORDER BY 1 )
SELECT
id,
from_address,
block_number,
tx_index,
amount_eth,
address_running_total,
preceding_running_total, eligible_amount,
SUM(eligible_amount) OVER (
ORDER BY block_number, tx_index
ROWS BETWEEN UNBOUNDED PRECEDING AND CURRENT ROW
) as global_total
FROM eligible_amounts
ORDER BY 1;
CREATE VIEW the_finalized_transactions_full_table AS
-- query name totally new
WITH running_totals AS (
-- Calculate running totals per address in transaction order
SELECT
id,
from_address,
amount_eth,
block_number,
tx_index,
SUM(amount_eth) OVER (
PARTITION BY from_address
ORDER BY block_number, tx_index
ROWS BETWEEN UNBOUNDED PRECEDING AND CURRENT ROW
) as address_running_total,
COALESCE(SUM(amount_eth) OVER (
PARTITION BY from_address
ORDER BY block_number, tx_index
ROWS BETWEEN UNBOUNDED PRECEDING AND 1 PRECEDING
), 0) as preceding_running_total
FROM donations_finalized
),
eligible_amounts AS (
--WITH the_big_temporary_table AS (
--we gon do some smart stuff here
SELECT
id,
from_address,
block_number,
tx_index,
amount_eth,
address_running_total,
preceding_running_total,
--these are eligible amount contributions for this particular transaction (not cumulative, unless previous donations have been too low..)
CASE
--not enough donations yet
WHEN address_running_total < 0.03 THEN 0
--already met the cap before this donation
WHEN preceding_running_total > 0.3 THEN 0
--previous donations under individual cap (if we are here in the struct, we have gone over cap already) contribution here will be either full address running total, or 0.3 if we go over the cap (ie running total > 0.3)
WHEN preceding_running_total < 0.03 THEN
LEAST(address_running_total, 0.3)
--if this transaction brought us over individual cap (and preceding cases excluded)
WHEN address_running_total > 0.3 THEN
(0.3 - preceding_running_total)
--all other cases
ELSE amount_eth
END
AS eligible_amount
FROM running_totals
ORDER BY 1 )
SELECT
id,
from_address,
block_number,
tx_index,
amount_eth,
address_running_total,
preceding_running_total, eligible_amount,
SUM(eligible_amount) OVER (
ORDER BY block_number, tx_index
ROWS BETWEEN UNBOUNDED PRECEDING AND CURRENT ROW
) as global_total
FROM eligible_amounts
ORDER BY 1;
CREATE VIEW address_totals AS
-- query name address totals
SELECT from_address, SUM(eligible_amount) AS eligible_amount, SUM(adjusted_amount_eth) AS total_amount_before_cutoff, SUM(amount_eth) AS total_amount_within_campaign_window
FROM (
SELECT id, from_address, amount_eth,
block_number, tx_index,
--this is where we do the cool stuff
CASE
WHEN global_total > 30.0 AND global_total - eligible_amount < 30.0
-- previous global total = global_total less eligible_amount
THEN 30.0 - (global_total - eligible_amount)
WHEN global_total > 30.0 THEN 0
ELSE eligible_amount
END as eligible_amount,
CASE
WHEN global_total > 30.0 AND global_total - eligible_amount < 30.0
-- previous global total = global_total less eligible_amount
THEN 30.0 - (global_total - eligible_amount)
WHEN global_total > 30.0 THEN 0
ELSE amount_eth
END as adjusted_amount_eth
FROM the_full_table
) as query1
GROUP BY from_address
ORDER BY 1;
CREATE VIEW address_totals_finalized AS
-- query name address totals finalized only
SELECT from_address, SUM(eligible_amount) AS eligible_amount, SUM(adjusted_amount_eth) AS total_amount_before_cutoff, SUM(amount_eth) AS total_amount_within_campaign_window
FROM (
SELECT id, from_address, amount_eth,
block_number, tx_index,
--this is where we do the cool stuff
CASE
WHEN global_total > 30.0 AND global_total - eligible_amount < 30.0
-- previous global total = global_total less eligible_amount
THEN 30.0 - (global_total - eligible_amount)
WHEN global_total > 30.0 THEN 0
ELSE eligible_amount
END as eligible_amount,
CASE
WHEN global_total > 30.0 AND global_total - eligible_amount < 30.0
-- previous global total = global_total less eligible_amount
THEN 30.0 - (global_total - eligible_amount)
WHEN global_total > 30.0 THEN 0
ELSE amount_eth
END as adjusted_amount_eth
FROM the_finalized_transactions_full_table
) as query1
GROUP BY from_address
ORDER BY 1;
CREATE VIEW eligible_addresses AS
-- query name eligible addresses (new version for topping tx capped up to 30 exactly)
SELECT * FROM address_totals
WHERE eligible_amount > 0;
CREATE VIEW eligible_addresses_finalized AS
-- query name eligible addresses (new version for topping tx capped up to 30 exactly)
SELECT * FROM address_totals_finalized
WHERE eligible_amount > 0;
CREATE VIEW donation_stats AS
-- query name donation stats
WITH temp AS (
SELECT
SUM(amount_eth) AS total_eth_donated,
COUNT(distinct from_address) AS total_participants,
COUNT(*) AS total_donations
FROM the_full_table
),
temp2 AS (
SELECT
--the following single stat is a little approximative and have room for improvement in some areas
COUNT(*) AS eligible_donations_approximative,
COUNT(distinct from_address) AS eligible_addresses
FROM the_full_table
WHERE eligible_amount > 0 AND
global_total - amount_eth < 30
)
SELECT
LEAST(
(SELECT MAX(global_total) FROM the_full_table),
30.0
) as eligible_total_eth,
(SELECT total_eth_donated from temp),
cutoff.block_number as cutoff_block,
cutoff.tx_index as cutoff_tx_index,
(SELECT total_participants FROM temp),
(SELECT total_donations FROM temp),
(SELECT eligible_donations_approximative FROM temp2),
(SELECT eligible_addresses FROM temp2)
FROM (
SELECT *
FROM the_full_table
WHERE global_total >= 30
ORDER BY block_number, tx_index
LIMIT 1
) cutoff
UNION
SELECT (SELECT MAX(global_total) FROM the_full_table) as eligible_total_eth,
(SELECT total_eth_donated FROM temp),
999999999999 as cutoff_block, 1 as cutoff_tx_index,
(SELECT total_participants FROM temp),
(SELECT total_donations FROM temp),
(SELECT eligible_donations_approximative FROM temp2),
(SELECT eligible_addresses FROM temp2)
WHERE (SELECT COUNT(*) FROM
(SELECT *
FROM the_full_table
WHERE global_total >= 30
ORDER BY block_number, tx_index
LIMIT 1) cutoff1)
< 1;
CREATE VIEW donation_stats_finalized AS
-- query name donation stats finalized
WITH temp AS (
SELECT
SUM(amount_eth) AS total_eth_donated,
COUNT(distinct from_address) AS total_participants,
COUNT(*) AS total_donations
FROM the_finalized_transactions_full_table
),
temp2 AS (
SELECT
--the following single stat is a little approximative and have room for improvement in some areas
COUNT(*) AS eligible_donations_approximative,
COUNT(distinct from_address) AS eligible_addresses
FROM the_finalized_transactions_full_table
WHERE eligible_amount > 0 AND
global_total - amount_eth < 30
)
SELECT
LEAST(
(SELECT MAX(global_total) FROM the_finalized_transactions_full_table),
30.0
) as eligible_total_eth,
(SELECT total_eth_donated from temp),
cutoff.block_number as cutoff_block,
cutoff.tx_index as cutoff_tx_index,
(SELECT total_participants FROM temp),
(SELECT total_donations FROM temp),
(SELECT eligible_donations_approximative FROM temp2),
(SELECT eligible_addresses FROM temp2)
FROM (
SELECT *
FROM the_finalized_transactions_full_table
WHERE global_total >= 30
ORDER BY block_number, tx_index
LIMIT 1
) cutoff
UNION
SELECT (SELECT MAX(global_total) FROM the_finalized_transactions_full_table) as eligible_total_eth,
(SELECT total_eth_donated FROM temp),
999999999999 as cutoff_block, 1 as cutoff_tx_index,
(SELECT total_participants FROM temp),
(SELECT total_donations FROM temp),
(SELECT eligible_donations_approximative FROM temp2),
(SELECT eligible_addresses FROM temp2)
WHERE (SELECT COUNT(*) FROM
(SELECT *
FROM the_finalized_transactions_full_table
WHERE global_total >= 30
ORDER BY block_number, tx_index
LIMIT 1) cutoff1)
< 1;