|
| 1 | +CREATE TABLE IF NOT EXISTS sectors_meta_updates ( |
| 2 | + singleton BOOLEAN PRIMARY KEY NOT NULL DEFAULT FALSE CHECK (singleton = FALSE), |
| 3 | + |
| 4 | + last_refresh_at TIMESTAMP WITH TIME ZONE, |
| 5 | + last_refresh_epoch BIGINT, |
| 6 | + last_refresh_tsk BYTEA |
| 7 | +); |
| 8 | + |
| 9 | +CREATE TABLE IF NOT EXISTS sectors_exp_buckets ( |
| 10 | + less_than_days INT NOT NULL PRIMARY KEY |
| 11 | +); |
| 12 | + |
| 13 | +CREATE INDEX IF NOT EXISTS sectors_exp_buckets_sorted_idx ON sectors_exp_buckets (less_than_days ASC); |
| 14 | + |
| 15 | +-- 1, 2, 3 weeks, useful for rolling deal extensions and main CC sector pool |
| 16 | +-- 180 days, 210 days, useful for rolling cc sector pools |
| 17 | +-- 360 days, 390 days, useful for rolling cc sector pools |
| 18 | +-- 540 days, 570 days, useful for rolling cc sector pools |
| 19 | +-- NOTE: this is a setting that users can manage through the UI |
| 20 | +INSERT INTO sectors_exp_buckets (less_than_days) VALUES (7), (14), (21), (28), (180), (210), (360), (390), (540), (570) ON CONFLICT DO NOTHING; |
| 21 | + |
| 22 | +-- Expiration manager |
| 23 | +-- Action types: |
| 24 | +-- 'extend' - "if any sector is in bucket A < exp < B, then extend all sectors A < exp < C to expiration D" |
| 25 | +-- - e.g. if any sector is expiring between 0 and 2 weeks extend all sectors between 0 and 3 weeks to 4 weeks |
| 26 | +-- 'top_up' - "if count(A < exp < B) < C then top up the bucket to D sectors, taking sectors from any duration less than A" |
| 27 | +-- - e.g. if there are less than 10 sectors expiring between 180 and 210 days, top up the bucket to 10 sectors, taking sectors from any duration less than 180 days |
| 28 | +CREATE TABLE IF NOT EXISTS sectors_exp_manager_presets ( |
| 29 | + name TEXT NOT NULL PRIMARY KEY, |
| 30 | + |
| 31 | + action_type TEXT NOT NULL CHECK (action_type IN ('extend', 'top_up')), |
| 32 | + |
| 33 | + -- info bucket we look at to determine if we need to extend or top up (both action types) |
| 34 | + info_bucket_above_days INT NOT NULL, |
| 35 | + info_bucket_below_days INT NOT NULL CHECK (info_bucket_above_days < info_bucket_below_days), |
| 36 | + |
| 37 | + -- target and max_extension expiration days in extend case, null for top_up (top_up extends to info_bucket_below_days) |
| 38 | + target_expiration_days BIGINT, |
| 39 | + max_candidate_days BIGINT, -- C in 'extend' action type |
| 40 | + |
| 41 | + -- top up count in top_up case, null for extend |
| 42 | + top_up_count_low_water_mark BIGINT, |
| 43 | + top_up_count_high_water_mark BIGINT, |
| 44 | + |
| 45 | + cc BOOLEAN, -- if true, only extend/top up CC sectors, if false just deals, if null - both |
| 46 | + drop_claims BOOLEAN NOT NULL DEFAULT FALSE, |
| 47 | + |
| 48 | + -- Ensure extend action has required fields |
| 49 | + CHECK (action_type != 'extend' OR (target_expiration_days IS NOT NULL AND max_candidate_days IS NOT NULL)), |
| 50 | + -- Ensure top_up action has required fields |
| 51 | + CHECK (action_type != 'top_up' OR (top_up_count_low_water_mark IS NOT NULL AND top_up_count_high_water_mark IS NOT NULL)), |
| 52 | + -- Ensure low water mark is less than high water mark for top_up |
| 53 | + CHECK (action_type != 'top_up' OR top_up_count_low_water_mark < top_up_count_high_water_mark) |
| 54 | +); |
| 55 | + |
| 56 | +CREATE TABLE IF NOT EXISTS sectors_exp_manager_sp ( |
| 57 | + sp_id BIGINT NOT NULL, |
| 58 | + preset_name TEXT NOT NULL, |
| 59 | + |
| 60 | + enabled BOOLEAN NOT NULL DEFAULT TRUE, |
| 61 | + |
| 62 | + last_run_at TIMESTAMP WITH TIME ZONE, |
| 63 | + |
| 64 | + last_message_cid TEXT, |
| 65 | + last_message_landed_at TIMESTAMP WITH TIME ZONE, |
| 66 | + |
| 67 | + PRIMARY KEY (sp_id, preset_name), |
| 68 | + FOREIGN KEY (preset_name) REFERENCES sectors_exp_manager_presets(name) ON DELETE RESTRICT |
| 69 | +); |
| 70 | + |
| 71 | +CREATE UNIQUE INDEX IF NOT EXISTS sectors_exp_manager_sp_last_message_cid_idx ON sectors_exp_manager_sp (last_message_cid); |
| 72 | + |
| 73 | +-- insert default presets |
| 74 | +INSERT INTO sectors_exp_manager_presets (name, action_type, info_bucket_above_days, info_bucket_below_days, target_expiration_days, max_candidate_days, top_up_count_low_water_mark, top_up_count_high_water_mark, cc, drop_claims) VALUES |
| 75 | +('roll_all_near_expiration', 'extend', 0, 14, 28, 21, NULL, NULL, NULL, FALSE), -- any in 0..14 days: extend all 0..21 days -> 28 days |
| 76 | +('cc_180d_pool', 'top_up', 180, 210, NULL, NULL, 100, 200, TRUE, FALSE), -- if less than 100 CC in 180..210 days: top up to 200 CC in 180..210 days |
| 77 | +('cc_360d_pool', 'top_up', 360, 390, NULL, NULL, 100, 200, TRUE, FALSE), -- if less than 100 CC in 360..390 days: top up to 200 CC in 360..390 days |
| 78 | +('cc_540d_pool', 'top_up', 540, 570, NULL, NULL, 100, 200, TRUE, FALSE) -- if less than 100 CC in 540..570 days: top up to 200 CC in 540..570 days |
| 79 | +ON CONFLICT DO NOTHING; |
| 80 | + |
| 81 | +ALTER TABLE sectors_meta ADD COLUMN IF NOT EXISTS min_claim_epoch BIGINT; |
| 82 | +ALTER TABLE sectors_meta ADD COLUMN IF NOT EXISTS max_claim_epoch BIGINT; |
| 83 | + |
| 84 | +-- Function to evaluate if a preset condition is met for an SP |
| 85 | +CREATE OR REPLACE FUNCTION eval_ext_mgr_sp_condition( |
| 86 | + p_sp_id BIGINT, |
| 87 | + p_preset_name TEXT, |
| 88 | + p_curr_epoch BIGINT, |
| 89 | + p_epoch_per_day NUMERIC DEFAULT 2880 |
| 90 | +) RETURNS BOOLEAN AS $$ |
| 91 | +DECLARE |
| 92 | + v_preset RECORD; |
| 93 | + v_count BIGINT; |
| 94 | + v_bucket_above_epoch BIGINT; |
| 95 | + v_bucket_below_epoch BIGINT; |
| 96 | +BEGIN |
| 97 | + -- Get preset configuration |
| 98 | + SELECT * INTO v_preset |
| 99 | + FROM sectors_exp_manager_presets |
| 100 | + WHERE name = p_preset_name; |
| 101 | + |
| 102 | + IF NOT FOUND THEN |
| 103 | + RETURN FALSE; -- Preset doesn't exist |
| 104 | + END IF; |
| 105 | + |
| 106 | + -- Calculate epoch boundaries for the info bucket |
| 107 | + v_bucket_above_epoch := p_curr_epoch + (v_preset.info_bucket_above_days * p_epoch_per_day); |
| 108 | + v_bucket_below_epoch := p_curr_epoch + (v_preset.info_bucket_below_days * p_epoch_per_day); |
| 109 | + |
| 110 | + IF v_preset.action_type = 'extend' THEN |
| 111 | + -- For 'extend': Check if ANY sector expires in the info bucket range |
| 112 | + -- Also filter by CC if specified |
| 113 | + -- Exclude sectors in snap pipeline or with open pieces |
| 114 | + SELECT COUNT(*) INTO v_count |
| 115 | + FROM sectors_meta sm |
| 116 | + WHERE sm.sp_id = p_sp_id |
| 117 | + AND sm.expiration_epoch IS NOT NULL |
| 118 | + AND sm.expiration_epoch > v_bucket_above_epoch |
| 119 | + AND sm.expiration_epoch < v_bucket_below_epoch |
| 120 | + AND (v_preset.cc IS NULL OR sm.is_cc = v_preset.cc) |
| 121 | + AND NOT EXISTS (SELECT 1 FROM sectors_snap_pipeline ssp WHERE ssp.sp_id = sm.sp_id AND ssp.sector_number = sm.sector_num) |
| 122 | + AND NOT EXISTS (SELECT 1 FROM open_sector_pieces osp WHERE osp.sp_id = sm.sp_id AND osp.sector_number = sm.sector_num); |
| 123 | + |
| 124 | + -- If any sector found in range, condition is met (needs extension) |
| 125 | + RETURN v_count > 0; |
| 126 | + |
| 127 | + ELSIF v_preset.action_type = 'top_up' THEN |
| 128 | + -- For 'top_up': Count sectors in the info bucket range |
| 129 | + -- Also filter by CC if specified |
| 130 | + -- Exclude sectors in snap pipeline or with open pieces |
| 131 | + SELECT COUNT(*) INTO v_count |
| 132 | + FROM sectors_meta sm |
| 133 | + WHERE sm.sp_id = p_sp_id |
| 134 | + AND sm.expiration_epoch IS NOT NULL |
| 135 | + AND sm.expiration_epoch > v_bucket_above_epoch |
| 136 | + AND sm.expiration_epoch < v_bucket_below_epoch |
| 137 | + AND (v_preset.cc IS NULL OR sm.is_cc = v_preset.cc) |
| 138 | + AND NOT EXISTS (SELECT 1 FROM sectors_snap_pipeline ssp WHERE ssp.sp_id = sm.sp_id AND ssp.sector_number = sm.sector_num) |
| 139 | + AND NOT EXISTS (SELECT 1 FROM open_sector_pieces osp WHERE osp.sp_id = sm.sp_id AND osp.sector_number = sm.sector_num); |
| 140 | + |
| 141 | + -- If count below low water mark, condition is met (needs top-up) |
| 142 | + RETURN v_count < COALESCE(v_preset.top_up_count_low_water_mark, 0); |
| 143 | + |
| 144 | + ELSE |
| 145 | + RETURN FALSE; -- Unknown action type |
| 146 | + END IF; |
| 147 | +END; |
| 148 | +$$ LANGUAGE plpgsql STABLE; |
| 149 | + |
| 150 | +CREATE OR REPLACE FUNCTION update_sectors_exp_manager_sp_from_message_waits() |
| 151 | +RETURNS trigger AS $$ |
| 152 | +BEGIN |
| 153 | + IF OLD.executed_tsk_epoch IS NULL AND NEW.executed_tsk_epoch IS NOT NULL THEN |
| 154 | + UPDATE sectors_exp_manager_sp |
| 155 | + SET last_message_landed_at = current_timestamp |
| 156 | + WHERE last_message_cid = NEW.signed_message_cid; |
| 157 | + END IF; |
| 158 | + RETURN NEW; |
| 159 | +END; |
| 160 | +$$ LANGUAGE plpgsql; |
| 161 | + |
| 162 | +DO $$ |
| 163 | +BEGIN |
| 164 | + IF NOT EXISTS ( |
| 165 | + SELECT 1 FROM pg_trigger |
| 166 | + WHERE tgname = 'tr_update_sectors_exp_manager_sp_from_message_waits' |
| 167 | + ) THEN |
| 168 | + CREATE TRIGGER tr_update_sectors_exp_manager_sp_from_message_waits AFTER UPDATE ON message_waits |
| 169 | +FOR EACH ROW |
| 170 | +WHEN (OLD.executed_tsk_epoch IS NULL AND NEW.executed_tsk_epoch IS NOT NULL) |
| 171 | +EXECUTE FUNCTION update_sectors_exp_manager_sp_from_message_waits(); |
| 172 | + END IF; |
| 173 | +END $$; |
| 174 | + |
0 commit comments