|
1 | 1 | #standardSQL
|
2 | 2 | -- MIT License
|
3 | 3 | -- Copyright (c) 2019 Yaz Khoury, [email protected]
|
4 |
| - |
5 |
| - |
6 |
| -WITH total_reward_book AS ( |
7 |
| - SELECT miner, |
8 |
| - DATE(timestamp) as date, |
9 |
| - COUNT(miner) as total_block_reward |
10 |
| - FROM `bigquery-public-data.crypto_ethereum_classic.blocks` |
11 |
| - GROUP BY miner, date |
12 |
| -), |
13 |
| -total_reward_book_by_date AS ( |
14 |
| - SELECT date, |
15 |
| - miner AS address, |
16 |
| - SUM(total_block_reward / POWER(10,0)) AS value |
17 |
| - FROM total_reward_book |
18 |
| - GROUP BY miner, date |
19 |
| -), |
20 |
| -daily_rewards_with_gaps AS ( |
21 |
| - SELECT |
22 |
| - address, |
23 |
| - date, |
24 |
| - SUM(value) OVER (PARTITION BY ADDRESS ORDER BY date) AS block_rewards, |
25 |
| - LEAD(date, 1, CURRENT_DATE()) OVER (PARTITION BY ADDRESS ORDER BY date) AS next_date |
26 |
| - FROM total_reward_book_by_date |
27 |
| -), |
28 |
| -calendar AS ( |
29 |
| - SELECT date |
30 |
| - FROM UNNEST(GENERATE_DATE_ARRAY('2015-07-30', CURRENT_DATE())) AS date |
31 |
| -), |
32 |
| -daily_rewards AS ( |
33 |
| - SELECT address, |
34 |
| - calendar.date, |
35 |
| - block_rewards |
36 |
| - FROM daily_rewards_with_gaps |
37 |
| - JOIN calendar ON daily_rewards_with_gaps.date <= calendar.date |
38 |
| - AND calendar.date < daily_rewards_with_gaps.next_date |
39 |
| -), |
40 |
| -supply AS ( |
41 |
| - SELECT date, |
42 |
| - SUM(block_rewards) AS total_rewards |
43 |
| - FROM daily_rewards |
44 |
| - GROUP BY date |
45 |
| -), |
46 |
| -ranked_daily_rewards AS ( |
47 |
| - SELECT daily_rewards.date AS date, |
48 |
| - block_rewards, |
49 |
| - ROW_NUMBER() OVER (PARTITION BY daily_rewards.date ORDER BY block_rewards DESC) AS rank |
50 |
| - FROM daily_rewards |
51 |
| - JOIN supply ON daily_rewards.date = supply.date |
52 |
| - WHERE SAFE_DIVIDE(block_rewards, total_rewards) >= 0.01 |
53 |
| - ORDER BY block_rewards DESC |
54 |
| -), |
55 |
| -daily_gini AS ( |
56 |
| - SELECT date, |
57 |
| - -- (1 − 2B) https://en.wikipedia.org/wiki/Gini_coefficient |
58 |
| - 1 - 2 * SUM((block_rewards * (rank - 1) + block_rewards / 2)) / COUNT(*) / SUM(block_rewards) AS gini |
59 |
| - FROM ranked_daily_rewards |
60 |
| - GROUP BY DATE |
61 |
| -) |
62 |
| -SELECT date, |
| 4 | +WITH |
| 5 | + total_reward_book AS ( |
| 6 | + SELECT |
| 7 | + miner, |
| 8 | + DATE(timestamp) AS date, |
| 9 | + COUNT(miner) AS total_block_reward |
| 10 | + FROM |
| 11 | + `bigquery-public-data.crypto_ethereum_classic.blocks` |
| 12 | + GROUP BY |
| 13 | + miner, |
| 14 | + date |
| 15 | + ), |
| 16 | + total_reward_book_by_date AS ( |
| 17 | + SELECT |
| 18 | + date, |
| 19 | + miner AS address, |
| 20 | + SUM(total_block_reward / POWER(10, 0)) AS value |
| 21 | + FROM |
| 22 | + total_reward_book |
| 23 | + GROUP BY |
| 24 | + miner, |
| 25 | + date |
| 26 | + ), |
| 27 | + daily_rewards_with_gaps AS ( |
| 28 | + SELECT |
| 29 | + address, |
| 30 | + date, |
| 31 | + SUM(value) OVER (PARTITION BY ADDRESS |
| 32 | + ORDER BY date) AS block_rewards, |
| 33 | + LEAD(date, 1, `CURRENT_DATE`()) OVER (PARTITION BY ADDRESS |
| 34 | + ORDER BY date) AS next_date |
| 35 | + FROM |
| 36 | + total_reward_book_by_date |
| 37 | + ), |
| 38 | + calendar AS ( |
| 39 | + SELECT |
| 40 | + date |
| 41 | + FROM |
| 42 | + UNNEST(GENERATE_DATE_ARRAY('2015-07-30', `CURRENT_DATE`())) AS date |
| 43 | + ), |
| 44 | + daily_rewards AS ( |
| 45 | + SELECT |
| 46 | + address, |
| 47 | + calendar.date, |
| 48 | + block_rewards |
| 49 | + FROM |
| 50 | + daily_rewards_with_gaps |
| 51 | + JOIN |
| 52 | + calendar |
| 53 | + ON daily_rewards_with_gaps.date <= calendar.date AND calendar.date < daily_rewards_with_gaps.next_date |
| 54 | + ), |
| 55 | + supply AS ( |
| 56 | + SELECT |
| 57 | + date, |
| 58 | + SUM(block_rewards) AS total_rewards |
| 59 | + FROM |
| 60 | + daily_rewards |
| 61 | + GROUP BY |
| 62 | + date |
| 63 | + ), |
| 64 | + ranked_daily_rewards AS ( |
| 65 | + SELECT |
| 66 | + daily_rewards.date AS date, |
| 67 | + block_rewards, |
| 68 | + ROW_NUMBER() OVER (PARTITION BY daily_rewards.date |
| 69 | + ORDER BY block_rewards DESC) AS rank |
| 70 | + FROM |
| 71 | + daily_rewards |
| 72 | + JOIN |
| 73 | + supply |
| 74 | + ON daily_rewards.date = supply.date |
| 75 | + WHERE |
| 76 | + SAFE_DIVIDE(block_rewards, total_rewards) >= 0.01 |
| 77 | + ORDER BY block_rewards DESC |
| 78 | + ), |
| 79 | + daily_gini AS ( |
| 80 | + SELECT |
| 81 | + date, |
| 82 | + -- (1 − 2B) https://en.wikipedia.org/wiki/Gini_coefficient |
| 83 | + 1 - 2 * SUM((block_rewards * (rank - 1) + block_rewards / 2)) / COUNT(*) / SUM(block_rewards) AS gini |
| 84 | + FROM |
| 85 | + ranked_daily_rewards |
| 86 | + GROUP BY |
| 87 | + DATE |
| 88 | + ) |
| 89 | +SELECT |
| 90 | + date, |
63 | 91 | gini,
|
64 |
| - AVG(gini) OVER (ORDER BY date ASC ROWS 7 PRECEDING) AS gini_sma_7, |
65 |
| - AVG(gini) OVER (ORDER BY date ASC ROWS 30 PRECEDING) AS gini_sma_30 |
66 |
| -FROM daily_gini |
| 92 | + AVG(gini) OVER ( |
| 93 | + ORDER BY date ROWS 7 PRECEDING) AS gini_sma_7, |
| 94 | + AVG(gini) OVER ( |
| 95 | + ORDER BY date ROWS 30 PRECEDING) AS gini_sma_30 |
| 96 | +FROM |
| 97 | + daily_gini; |
0 commit comments