|
| 1 | +SELECT insert_verification_value( |
| 2 | + distribution_number => 20, |
| 3 | + type => 'send_token_hodler'::public.verification_type, |
| 4 | + multiplier_min => 0, |
| 5 | + multiplier_max => 0, |
| 6 | + multiplier_step => 0 |
| 7 | +); |
| 8 | + |
| 9 | + |
| 10 | +-- Data backfill: populate token_balances from historical send_token_transfers |
| 11 | +-- Goal: sum all transfers (in - out since account creation) for SEND token and upsert into token_balances |
| 12 | +-- Safe to re-run: uses ON CONFLICT to overwrite balance with final sum. |
| 13 | + |
| 14 | +DO $$ |
| 15 | +BEGIN |
| 16 | + -- Ensure the token_balances table exists (created in prior migration); if not, abort early |
| 17 | + IF NOT EXISTS ( |
| 18 | + SELECT 1 FROM information_schema.tables |
| 19 | + WHERE table_schema = 'public' AND table_name = 'token_balances' |
| 20 | + ) THEN |
| 21 | + RAISE NOTICE 'token_balances does not exist; skipping backfill.'; |
| 22 | + RETURN; |
| 23 | + END IF; |
| 24 | + |
| 25 | + WITH send_token AS ( |
| 26 | + SELECT decode('Eab49138BA2Ea6dd776220fE26b7b8E446638956','hex') AS token |
| 27 | + ), |
| 28 | + sa AS ( |
| 29 | + SELECT sa.user_id, |
| 30 | + sa.address, |
| 31 | + sa.chain_id, |
| 32 | + decode(replace(sa.address::text,'0x',''),'hex') AS addr_bytea |
| 33 | + FROM public.send_accounts sa |
| 34 | + ), |
| 35 | + di AS ( |
| 36 | + SELECT sa.user_id, |
| 37 | + sa.address, |
| 38 | + sa.chain_id, |
| 39 | + SUM(stt.v)::numeric AS amt_in, |
| 40 | + MAX(stt.block_time) AS max_bt |
| 41 | + FROM sa |
| 42 | + JOIN public.send_account_created sac ON sac.account = sa.addr_bytea |
| 43 | + JOIN public.send_token_transfers stt |
| 44 | + ON stt.t = sa.addr_bytea |
| 45 | + AND stt.log_addr = (SELECT token FROM send_token) |
| 46 | + AND stt.block_num >= sac.block_num |
| 47 | + GROUP BY sa.user_id, sa.address, sa.chain_id |
| 48 | + ), |
| 49 | + dout AS ( |
| 50 | + SELECT sa.user_id, |
| 51 | + sa.address, |
| 52 | + sa.chain_id, |
| 53 | + SUM(stt.v)::numeric AS amt_out, |
| 54 | + MAX(stt.block_time) AS max_bt |
| 55 | + FROM sa |
| 56 | + JOIN public.send_account_created sac ON sac.account = sa.addr_bytea |
| 57 | + JOIN public.send_token_transfers stt |
| 58 | + ON stt.f = sa.addr_bytea |
| 59 | + AND stt.log_addr = (SELECT token FROM send_token) |
| 60 | + AND stt.block_num >= sac.block_num |
| 61 | + GROUP BY sa.user_id, sa.address, sa.chain_id |
| 62 | + ), |
| 63 | + final AS ( |
| 64 | + SELECT COALESCE(di.user_id, dout.user_id) AS user_id, |
| 65 | + COALESCE(di.address, dout.address) AS address, |
| 66 | + COALESCE(di.chain_id, dout.chain_id) AS chain_id, |
| 67 | + (COALESCE(di.amt_in, 0) - COALESCE(dout.amt_out, 0))::numeric AS balance, |
| 68 | + GREATEST(COALESCE(di.max_bt, 0), COALESCE(dout.max_bt, 0)) AS max_block_time |
| 69 | + FROM di |
| 70 | + FULL OUTER JOIN dout ON di.user_id = dout.user_id |
| 71 | + AND di.address = dout.address |
| 72 | + AND di.chain_id = dout.chain_id |
| 73 | + ), |
| 74 | + -- ETH/native deposits: sum receives where recipient is a Send Account and sender is NOT a Send Account |
| 75 | + eth_dep AS ( |
| 76 | + SELECT sa.user_id, |
| 77 | + sa.address, |
| 78 | + sa.chain_id, |
| 79 | + SUM(rec.value)::numeric AS amt_dep, |
| 80 | + MAX(rec.block_time) AS max_bt |
| 81 | + FROM sa |
| 82 | + JOIN public.send_account_created sac ON sac.account = sa.addr_bytea |
| 83 | + JOIN public.send_account_receives rec |
| 84 | + ON rec.log_addr = sa.addr_bytea |
| 85 | + AND rec.chain_id = sa.chain_id |
| 86 | + AND rec.block_num >= sac.block_num |
| 87 | + LEFT JOIN public.send_accounts sa_sender |
| 88 | + ON sa_sender.address = concat('0x', encode(rec.sender, 'hex'))::citext |
| 89 | + AND sa_sender.chain_id = sa.chain_id |
| 90 | + WHERE sa_sender.id IS NULL -- deposits only (external → Send Account) |
| 91 | + GROUP BY sa.user_id, sa.address, sa.chain_id |
| 92 | + ) |
| 93 | + -- Insert SEND token balances |
| 94 | + INSERT INTO public.token_balances(user_id, address, chain_id, token, balance, updated_at) |
| 95 | + SELECT f.user_id, |
| 96 | + f.address, |
| 97 | + f.chain_id, |
| 98 | + (SELECT token FROM send_token), |
| 99 | + f.balance, |
| 100 | + CASE WHEN f.max_block_time > 0 THEN to_timestamp(f.max_block_time) AT TIME ZONE 'UTC' |
| 101 | + ELSE now() AT TIME ZONE 'UTC' END |
| 102 | + FROM final f |
| 103 | + ON CONFLICT (user_id, token_key) DO UPDATE |
| 104 | + SET balance = EXCLUDED.balance, |
| 105 | + address = EXCLUDED.address, |
| 106 | + chain_id = EXCLUDED.chain_id, |
| 107 | + updated_at = EXCLUDED.updated_at; |
| 108 | + |
| 109 | + -- Insert ETH/native deposit balances (token = NULL) |
| 110 | + WITH sa AS ( |
| 111 | + SELECT sa.user_id, |
| 112 | + sa.address, |
| 113 | + sa.chain_id, |
| 114 | + decode(replace(sa.address::text,'0x',''),'hex') AS addr_bytea |
| 115 | + FROM public.send_accounts sa |
| 116 | + ), |
| 117 | + eth_dep AS ( |
| 118 | + SELECT sa.user_id, |
| 119 | + sa.address, |
| 120 | + sa.chain_id, |
| 121 | + SUM(rec.value)::numeric AS amt_dep, |
| 122 | + MAX(rec.block_time) AS max_bt |
| 123 | + FROM sa |
| 124 | + JOIN public.send_account_created sac ON sac.account = sa.addr_bytea |
| 125 | + JOIN public.send_account_receives rec |
| 126 | + ON rec.log_addr = sa.addr_bytea |
| 127 | + AND rec.chain_id = sa.chain_id |
| 128 | + AND rec.block_num >= sac.block_num |
| 129 | + LEFT JOIN public.send_accounts sa_sender |
| 130 | + ON sa_sender.address = concat('0x', encode(rec.sender, 'hex'))::citext |
| 131 | + AND sa_sender.chain_id = sa.chain_id |
| 132 | + WHERE sa_sender.id IS NULL -- deposits only (external → Send Account) |
| 133 | + GROUP BY sa.user_id, sa.address, sa.chain_id |
| 134 | + ) |
| 135 | + INSERT INTO public.token_balances(user_id, address, chain_id, token, balance, updated_at) |
| 136 | + SELECT ed.user_id, |
| 137 | + ed.address, |
| 138 | + ed.chain_id, |
| 139 | + NULL AS token, |
| 140 | + ed.amt_dep, |
| 141 | + CASE WHEN ed.max_bt > 0 THEN to_timestamp(ed.max_bt) AT TIME ZONE 'UTC' |
| 142 | + ELSE now() AT TIME ZONE 'UTC' END |
| 143 | + FROM eth_dep ed |
| 144 | + ON CONFLICT (user_id, token_key) DO UPDATE |
| 145 | + SET balance = public.token_balances.balance + EXCLUDED.balance, |
| 146 | + address = EXCLUDED.address, |
| 147 | + chain_id = EXCLUDED.chain_id, |
| 148 | + updated_at = EXCLUDED.updated_at; |
| 149 | +END $$; |
0 commit comments