|
| 1 | +CREATE OR REPLACE FUNCTION sum_qualification_sends(distribution_number integer) |
| 2 | + RETURNS TABLE( |
| 3 | + user_id uuid, |
| 4 | + amount numeric, |
| 5 | + sent_to citext[]) |
| 6 | + LANGUAGE plpgsql |
| 7 | + AS $$ |
| 8 | +BEGIN |
| 9 | + -- Create temporary table to store qualification period |
| 10 | + CREATE TEMPORARY TABLE IF NOT EXISTS qual_period AS |
| 11 | + SELECT |
| 12 | + extract(epoch FROM qualification_start) AS start_time, |
| 13 | + extract(epoch FROM qualification_end) AS end_time |
| 14 | + FROM |
| 15 | + distributions |
| 16 | + WHERE |
| 17 | + number = $1; |
| 18 | + -- Create temporary table for first sends to each address |
| 19 | + CREATE TEMPORARY TABLE first_sends AS SELECT DISTINCT ON(sa.user_id, concat('0x', encode(stt.t, 'hex') |
| 20 | +)::citext) sa.user_id, |
| 21 | + concat('0x', encode(stt.t, 'hex'))::citext AS recipient, |
| 22 | + stt.v AS send_amount, -- Store full amount, will cap later |
| 23 | + stt.block_time |
| 24 | +FROM |
| 25 | + send_token_transfers stt |
| 26 | + JOIN send_accounts sa ON sa.address = concat('0x', encode(stt.f, 'hex'))::citext |
| 27 | + CROSS JOIN qual_period qp |
| 28 | +WHERE |
| 29 | + stt.block_time >= qp.start_time |
| 30 | + AND stt.block_time < qp.end_time |
| 31 | + ORDER BY |
| 32 | + sa.user_id, |
| 33 | + concat('0x', encode(stt.t, 'hex'))::citext, |
| 34 | + stt.block_time; |
| 35 | + -- Create index for performance |
| 36 | + CREATE INDEX ON first_sends(user_id); |
| 37 | + -- Return aggregated results with per-user send ceiling |
| 38 | + RETURN QUERY |
| 39 | + SELECT |
| 40 | + fs.user_id, |
| 41 | + SUM(LEAST(fs.send_amount, scs.send_ceiling)) AS amount, |
| 42 | + array_agg(fs.recipient) AS sent_to |
| 43 | + FROM |
| 44 | + first_sends fs |
| 45 | + JOIN send_ceiling_settings scs ON fs.user_id = scs.user_id |
| 46 | + GROUP BY |
| 47 | + fs.user_id; |
| 48 | + -- Cleanup |
| 49 | + DROP TABLE IF EXISTS qual_period; |
| 50 | + DROP TABLE IF EXISTS first_sends; |
| 51 | +END; |
| 52 | +$$; |
| 53 | + |
| 54 | +CREATE OR REPLACE FUNCTION calculate_and_insert_send_ceiling_verification(distribution_number integer) |
| 55 | + RETURNS void |
| 56 | + LANGUAGE plpgsql |
| 57 | + AS $$ |
| 58 | +BEGIN |
| 59 | + CREATE TEMPORARY TABLE send_ceiling_settings AS |
| 60 | + WITH send_settings AS( |
| 61 | + SELECT |
| 62 | + minimum_sends * scaling_divisor AS divider |
| 63 | + FROM |
| 64 | + send_slash s_s |
| 65 | + WHERE |
| 66 | + s_s.distribution_number = $1 |
| 67 | +), |
| 68 | +previous_distribution AS( |
| 69 | + SELECT |
| 70 | + ds.user_id, |
| 71 | + ds.amount AS user_prev_shares |
| 72 | + FROM |
| 73 | + distribution_shares ds |
| 74 | + WHERE |
| 75 | + ds.distribution_id =( |
| 76 | + SELECT |
| 77 | + id |
| 78 | + FROM |
| 79 | + distributions d |
| 80 | + WHERE |
| 81 | + d.number = $1 - 1)) |
| 82 | +SELECT |
| 83 | + pd.user_id, |
| 84 | + ROUND(COALESCE(pd.user_prev_shares, d.hodler_min_balance) / ss.divider)::numeric AS send_ceiling |
| 85 | +FROM |
| 86 | + distributions d |
| 87 | + CROSS JOIN send_settings ss |
| 88 | + LEFT JOIN previous_distribution pd ON TRUE |
| 89 | +WHERE |
| 90 | + d.number = $1; |
| 91 | + CREATE TEMPORARY TABLE all_qualifying_sends AS |
| 92 | + SELECT |
| 93 | + * |
| 94 | + FROM |
| 95 | + sum_qualification_sends($1); |
| 96 | + INSERT INTO distribution_verifications( |
| 97 | + distribution_id, |
| 98 | + user_id, |
| 99 | + type, |
| 100 | + weight, |
| 101 | + metadata) |
| 102 | + SELECT |
| 103 | +( |
| 104 | + SELECT |
| 105 | + id |
| 106 | + FROM |
| 107 | + distributions d |
| 108 | + WHERE |
| 109 | + d.number = $1), qs.user_id, 'send_ceiling'::public.verification_type, qs.amount, -- amount is already capped per user in sum_qualification_sends |
| 110 | + jsonb_build_object('value', scs.send_ceiling, 'sent_to', qs.sent_to) |
| 111 | + FROM |
| 112 | + send_ceiling_settings scs |
| 113 | + JOIN all_qualifying_sends qs ON qs.user_id = scs.user_id |
| 114 | + WHERE |
| 115 | + COALESCE(qs.amount, 0) > 0; |
| 116 | +END; |
| 117 | +$$; |
| 118 | + |
| 119 | +SELECT |
| 120 | + calculate_and_insert_send_ceiling_verification(9); |
| 121 | + |
| 122 | +-- Cleanup temporary tables |
| 123 | +DROP TABLE IF EXISTS send_ceiling_settings; |
| 124 | + |
| 125 | +DROP TABLE IF EXISTS all_qualifying_sends; |
| 126 | + |
| 127 | +CREATE OR REPLACE FUNCTION insert_verification_send_ceiling() |
| 128 | + RETURNS TRIGGER |
| 129 | + LANGUAGE plpgsql |
| 130 | + AS $$ |
| 131 | +DECLARE |
| 132 | + _user_id uuid; |
| 133 | + _recipient_address citext; |
| 134 | + _distribution_id integer; |
| 135 | + _distribution_number integer; |
| 136 | + _send_ceiling numeric; |
| 137 | + _verification_exists boolean; |
| 138 | +BEGIN |
| 139 | + -- Get the sender's user_id |
| 140 | + SELECT |
| 141 | + user_id INTO _user_id |
| 142 | + FROM |
| 143 | + send_accounts |
| 144 | + WHERE |
| 145 | + address = concat('0x', encode(NEW.f, 'hex'))::citext; |
| 146 | + -- Get recipient address |
| 147 | + _recipient_address := concat('0x', encode(NEW.t, 'hex'))::citext; |
| 148 | + -- Get the active distribution id and number |
| 149 | + SELECT |
| 150 | + d.id, |
| 151 | + d.number INTO _distribution_id, |
| 152 | + _distribution_number |
| 153 | + FROM |
| 154 | + distributions d |
| 155 | + WHERE |
| 156 | + extract(epoch FROM d.qualification_start) <= NEW.block_time |
| 157 | + AND extract(epoch FROM d.qualification_end) > NEW.block_time; |
| 158 | + -- If we found matching distribution and user |
| 159 | + IF _user_id IS NOT NULL AND _distribution_id IS NOT NULL THEN |
| 160 | + -- Check if verification exists |
| 161 | + SELECT |
| 162 | + EXISTS ( |
| 163 | + SELECT |
| 164 | + 1 |
| 165 | + FROM |
| 166 | + distribution_verifications |
| 167 | + WHERE |
| 168 | + user_id = _user_id |
| 169 | + AND distribution_id = _distribution_id |
| 170 | + AND type = 'send_ceiling') INTO _verification_exists; |
| 171 | + IF NOT _verification_exists THEN |
| 172 | + -- Get send ceiling using the same logic as send_ceiling_settings table |
| 173 | + WITH send_settings AS ( |
| 174 | + SELECT |
| 175 | + minimum_sends * scaling_divisor AS divider |
| 176 | + FROM |
| 177 | + send_slash s_s |
| 178 | + WHERE |
| 179 | + s_s.distribution_number = _distribution_number |
| 180 | +), |
| 181 | +previous_distribution AS ( |
| 182 | + SELECT |
| 183 | + ds.amount AS user_prev_shares |
| 184 | + FROM |
| 185 | + distribution_shares ds |
| 186 | + WHERE |
| 187 | + ds.distribution_id =( |
| 188 | + SELECT |
| 189 | + id |
| 190 | + FROM |
| 191 | + distributions |
| 192 | + WHERE |
| 193 | + number = _distribution_number - 1) |
| 194 | + AND ds.user_id = _user_id |
| 195 | +), |
| 196 | +distribution_info AS ( |
| 197 | + SELECT |
| 198 | + hodler_min_balance |
| 199 | + FROM |
| 200 | + distributions |
| 201 | + WHERE |
| 202 | + id = _distribution_id |
| 203 | +) |
| 204 | +SELECT |
| 205 | + ROUND(COALESCE(pd.user_prev_shares, di.hodler_min_balance) / ss.divider)::numeric INTO _send_ceiling |
| 206 | +FROM |
| 207 | + distribution_info di |
| 208 | + CROSS JOIN send_settings ss |
| 209 | + LEFT JOIN previous_distribution pd ON TRUE; |
| 210 | + -- Create new verification |
| 211 | + INSERT INTO distribution_verifications( |
| 212 | + distribution_id, |
| 213 | + user_id, |
| 214 | + type, |
| 215 | + weight, |
| 216 | + metadata) |
| 217 | + VALUES ( |
| 218 | + _distribution_id, |
| 219 | + _user_id, |
| 220 | + 'send_ceiling', |
| 221 | + LEAST( |
| 222 | + NEW.v, _send_ceiling), |
| 223 | + jsonb_build_object( |
| 224 | + 'value', _send_ceiling, 'sent_to', ARRAY[_recipient_address])); |
| 225 | +ELSE |
| 226 | + -- Get the send ceiling for existing verification |
| 227 | + SELECT |
| 228 | + (metadata ->> 'value')::numeric INTO _send_ceiling |
| 229 | + FROM |
| 230 | + distribution_verifications |
| 231 | + WHERE |
| 232 | + user_id = _user_id |
| 233 | + AND distribution_id = _distribution_id |
| 234 | + AND type = 'send_ceiling'; |
| 235 | + -- Update existing verification, only if this recipient hasn't been counted before |
| 236 | + UPDATE |
| 237 | + distribution_verifications |
| 238 | + SET |
| 239 | + metadata = jsonb_set(metadata, '{sent_to}', to_jsonb(array_append(COALESCE(metadata -> 'sent_to'::citext[], ARRAY[]::citext[]), _recipient_address))), |
| 240 | + weight = weight + LEAST(NEW.v, _send_ceiling) |
| 241 | + WHERE |
| 242 | + user_id = _user_id |
| 243 | + AND distribution_id = _distribution_id |
| 244 | + AND type = 'send_ceiling' |
| 245 | + AND NOT (_recipient_address = ANY (metadata -> 'sent_to'::citext[])); |
| 246 | +END IF; |
| 247 | +END IF; |
| 248 | + RETURN NEW; |
| 249 | +END; |
| 250 | +$$; |
| 251 | + |
0 commit comments