|
7 | 7 | ) |
8 | 8 |
|
9 | 9 | const operatorAllocationSnapshotsQuery = ` |
10 | | - insert into operator_allocation_snapshots(operator, avs, strategy, operator_set_id, magnitude, snapshot) |
| 10 | + insert into operator_allocation_snapshots(operator, avs, strategy, operator_set_id, magnitude, max_magnitude, snapshot) |
11 | 11 | WITH ranked_allocation_records as ( |
12 | 12 | SELECT *, |
13 | 13 | ROW_NUMBER() OVER (PARTITION BY operator, avs, strategy, operator_set_id, cast(block_time AS DATE) ORDER BY block_time DESC, log_index DESC) AS rn |
@@ -86,16 +86,48 @@ const operatorAllocationSnapshotsQuery = ` |
86 | 86 | cleaned_records as ( |
87 | 87 | SELECT * FROM allocation_windows |
88 | 88 | WHERE start_time < end_time |
| 89 | + ), |
| 90 | + -- Get the latest max_magnitude for each (operator, strategy) as of the cutoff date |
| 91 | + latest_max_magnitudes as ( |
| 92 | + SELECT |
| 93 | + omm.operator, |
| 94 | + omm.strategy, |
| 95 | + omm.max_magnitude, |
| 96 | + ROW_NUMBER() OVER ( |
| 97 | + PARTITION BY omm.operator, omm.strategy |
| 98 | + ORDER BY omm.block_number DESC, omm.log_index DESC |
| 99 | + ) AS rn |
| 100 | + FROM operator_max_magnitudes omm |
| 101 | + INNER JOIN blocks b ON omm.block_number = b.number |
| 102 | + WHERE b.block_time < TIMESTAMP '{{.cutoffDate}}' |
| 103 | + ), |
| 104 | + -- Join allocations with max_magnitudes |
| 105 | + allocations_with_max as ( |
| 106 | + SELECT |
| 107 | + cr.operator, |
| 108 | + cr.avs, |
| 109 | + cr.strategy, |
| 110 | + cr.operator_set_id, |
| 111 | + cr.magnitude, |
| 112 | + COALESCE(lmm.max_magnitude, '0') as max_magnitude, |
| 113 | + cr.start_time, |
| 114 | + cr.end_time |
| 115 | + FROM cleaned_records cr |
| 116 | + LEFT JOIN latest_max_magnitudes lmm |
| 117 | + ON cr.operator = lmm.operator |
| 118 | + AND cr.strategy = lmm.strategy |
| 119 | + AND lmm.rn = 1 |
89 | 120 | ) |
90 | 121 | SELECT |
91 | 122 | operator, |
92 | 123 | avs, |
93 | 124 | strategy, |
94 | 125 | operator_set_id, |
95 | 126 | magnitude, |
| 127 | + max_magnitude, |
96 | 128 | cast(day AS DATE) AS snapshot |
97 | 129 | FROM |
98 | | - cleaned_records |
| 130 | + allocations_with_max |
99 | 131 | CROSS JOIN |
100 | 132 | generate_series(DATE(start_time), DATE(end_time) - interval '1' day, interval '1' day) AS day |
101 | 133 | on conflict do nothing; |
|
0 commit comments