|
19 | 19 | -- power_actor_claims is change-driven: a miner only has a row on days their power changed. |
20 | 20 | -- To get stable total-network-power per day we must fill-forward each miner's last known |
21 | 21 | -- power to days they are absent, then sum across all miners, then diff day-over-day. |
| 22 | +-- |
| 23 | +-- Bug fix: miners whose power was established before height 4000000 had no baseline, |
| 24 | +-- so their full historical power appeared as a spike on day 1 of the analysis window. |
| 25 | +-- We fix this by seeding each miner's initial state from their last known power at or |
| 26 | +-- before height 4000000 and injecting it as a virtual anchor entry on the day before |
| 27 | +-- the analysis window opens. |
22 | 28 | with activity as ( |
23 | | - -- Last known power per miner per day (only days they had activity) |
| 29 | + -- Last known power per miner per day (only days they had activity in-window) |
24 | 30 | select |
25 | 31 | datetime_trunc(timestamp_seconds(((height * 30) + 1598306400)), day) as date, |
26 | 32 | miner_id, |
|
40 | 46 | from activity |
41 | 47 | where rn = 1 |
42 | 48 | ), |
43 | | -date_spine as (select distinct date from daily_activity), |
44 | | -miner_bounds as ( |
45 | | - select miner_id, min(date) as first_seen_date |
46 | | - from daily_activity |
47 | | - group by 1 |
| 49 | +-- Seed: last known power per miner at or before the window boundary. |
| 50 | +-- Only fetch miners that actually appear in the analysis window (inner join) |
| 51 | +-- to keep the cross-join bounded. |
| 52 | +seed_raw as ( |
| 53 | + select |
| 54 | + p.miner_id, |
| 55 | + cast(p.raw_byte_power as float64) as raw_byte_power, |
| 56 | + cast(p.quality_adj_power as float64) as quality_adj_power, |
| 57 | + row_number() over (partition by p.miner_id order by p.height desc) as rn |
| 58 | + from `lily-data.lily.power_actor_claims` p |
| 59 | + inner join (select distinct miner_id from daily_activity) m using (miner_id) |
| 60 | + where p.height <= 4000000 |
| 61 | +), |
| 62 | +seed_latest as ( |
| 63 | + select miner_id, raw_byte_power, quality_adj_power |
| 64 | + from seed_raw |
| 65 | + where rn = 1 |
| 66 | +), |
| 67 | +-- Virtual anchor row: inject seed power as an entry on the day before the window opens. |
| 68 | +-- The fill-forward carries these values into day 1, so the first real diff is correct. |
| 69 | +seed_anchor as ( |
| 70 | + select |
| 71 | + date_sub((select min(date) from daily_activity), interval 1 day) as date, |
| 72 | + s.miner_id, |
| 73 | + s.raw_byte_power, |
| 74 | + s.quality_adj_power |
| 75 | + from seed_latest s |
| 76 | +), |
| 77 | +-- Merge the anchor entries with actual in-window activity |
| 78 | +all_activity as ( |
| 79 | + select date, miner_id, raw_byte_power, quality_adj_power from daily_activity |
| 80 | + union all |
| 81 | + select date, miner_id, raw_byte_power, quality_adj_power from seed_anchor |
48 | 82 | ), |
49 | | --- All date × miner combinations from each miner's first-seen day onward |
| 83 | +date_spine as (select distinct date from all_activity), |
| 84 | +miner_spine as (select distinct miner_id from all_activity), |
| 85 | +-- All date × miner combinations (includes the anchor date) |
50 | 86 | all_combos as ( |
51 | 87 | select d.date, m.miner_id |
52 | | - from date_spine d |
53 | | - join miner_bounds m |
54 | | - on d.date >= m.first_seen_date |
| 88 | + from date_spine d cross join miner_spine m |
55 | 89 | ), |
56 | 90 | -- Fill-forward: carry each miner's last known power through subsequent days |
57 | 91 | filled as ( |
58 | 92 | select |
59 | 93 | a.date, |
60 | 94 | a.miner_id, |
61 | | - last_value(da.raw_byte_power ignore nulls) over ( |
| 95 | + last_value(aa.raw_byte_power ignore nulls) over ( |
62 | 96 | partition by a.miner_id order by a.date |
63 | 97 | rows between unbounded preceding and current row |
64 | 98 | ) as raw_byte_power, |
65 | | - last_value(da.quality_adj_power ignore nulls) over ( |
| 99 | + last_value(aa.quality_adj_power ignore nulls) over ( |
66 | 100 | partition by a.miner_id order by a.date |
67 | 101 | rows between unbounded preceding and current row |
68 | 102 | ) as quality_adj_power |
69 | 103 | from all_combos a |
70 | | - left join daily_activity da on a.date = da.date and a.miner_id = da.miner_id |
71 | | -), |
72 | | --- First observation per miner has no prior baseline, so skip it in delta sums. |
73 | | -deltas as ( |
74 | | - select |
75 | | - date, |
76 | | - miner_id, |
77 | | - case |
78 | | - when lag(raw_byte_power) over (partition by miner_id order by date) is null then null |
79 | | - else raw_byte_power - lag(raw_byte_power) over (partition by miner_id order by date) |
80 | | - end as raw_delta, |
81 | | - case |
82 | | - when lag(quality_adj_power) over (partition by miner_id order by date) is null then null |
83 | | - else quality_adj_power - lag(quality_adj_power) over (partition by miner_id order by date) |
84 | | - end as qap_delta |
85 | | - from filled |
| 104 | + left join all_activity aa on a.date = aa.date and a.miner_id = aa.miner_id |
86 | 105 | ), |
87 | 106 | network_daily as ( |
88 | 107 | select |
89 | 108 | date, |
90 | | - sum(coalesce(raw_delta, 0)) as raw_power_added_bytes, |
91 | | - sum(coalesce(qap_delta, 0)) as qap_power_added_bytes |
92 | | - from deltas |
| 109 | + sum(coalesce(raw_byte_power, 0)) as total_raw, |
| 110 | + sum(coalesce(quality_adj_power, 0)) as total_qap |
| 111 | + from filled |
93 | 112 | group by 1 |
94 | 113 | ) |
95 | 114 | select |
96 | 115 | date, |
97 | | - raw_power_added_bytes / pow(1024, 5) as raw_power_added, |
98 | | - qap_power_added_bytes / pow(1024, 5) as quality_adjusted_power_added |
| 116 | + (total_raw - lag(total_raw) over (order by date)) / pow(1024, 5) as raw_power_added, |
| 117 | + (total_qap - lag(total_qap) over (order by date)) / pow(1024, 5) as quality_adjusted_power_added |
99 | 118 | from network_daily |
| 119 | +-- Exclude the synthetic anchor day; it exists only to seed the fill-forward |
| 120 | +where date >= (select min(date) from daily_activity) |
100 | 121 | order by date desc |
101 | 122 | """ |
102 | 123 |
|
103 | 124 | data = client.query(sql).to_arrow(create_bqstorage_client=False) |
104 | 125 |
|
105 | | -df = pl.DataFrame(data).with_columns(pl.col("date").dt.strftime("%Y-%m-%d")) |
| 126 | +# Apply 7-day trailing rolling mean to smooth single-day spikes caused by |
| 127 | +# timing/reporting artifacts in power_actor_claims (e.g. large power changes |
| 128 | +# split across day boundaries). The chart subtitle reflects this smoothing. |
| 129 | +df = ( |
| 130 | + pl.DataFrame(data) |
| 131 | + .with_columns(pl.col("date").dt.strftime("%Y-%m-%d")) |
| 132 | + .sort("date") |
| 133 | + .with_columns([ |
| 134 | + pl.col("raw_power_added") |
| 135 | + .rolling_mean(window_size=7, min_samples=1) |
| 136 | + .alias("raw_power_added"), |
| 137 | + pl.col("quality_adjusted_power_added") |
| 138 | + .rolling_mean(window_size=7, min_samples=1) |
| 139 | + .alias("quality_adjusted_power_added"), |
| 140 | + ]) |
| 141 | + .sort("date", descending=True) |
| 142 | +) |
106 | 143 |
|
107 | 144 | df.write_json(f"public/{Path(__file__).stem}.json") |
0 commit comments