|
| 1 | +/** @param { import("node-pg-migrate").MigrationBuilder } pgm */ |
| 2 | +exports.up = pgm => { |
| 3 | + pgm.createTable('ft_balances', { |
| 4 | + id: { |
| 5 | + type: 'bigserial', |
| 6 | + primaryKey: true, |
| 7 | + }, |
| 8 | + address: { |
| 9 | + type: 'text', |
| 10 | + notNull: true, |
| 11 | + }, |
| 12 | + token: { |
| 13 | + type: 'text', |
| 14 | + notNull: true, |
| 15 | + }, |
| 16 | + balance: { |
| 17 | + type: 'numeric', |
| 18 | + notNull: true, |
| 19 | + } |
| 20 | + }); |
| 21 | + |
| 22 | + pgm.addConstraint('ft_balances', 'unique_address_token', `UNIQUE(address, token)`); |
| 23 | + |
| 24 | + // Speeds up "grab the addresses with the highest balance for a given token" queries |
| 25 | + pgm.createIndex('ft_balances', [{ name: 'token' }, { name: 'balance', sort: 'DESC' }]); |
| 26 | + |
| 27 | + // Speeds up "get the total supply of a given token" queries |
| 28 | + pgm.createIndex('ft_balances', 'token'); |
| 29 | + |
| 30 | + // Populate the table with the current stx balances |
| 31 | + pgm.sql(` |
| 32 | + WITH all_balances AS ( |
| 33 | + SELECT sender AS address, -SUM(amount) AS balance_change |
| 34 | + FROM stx_events |
| 35 | + WHERE asset_event_type_id IN (1, 3) -- Transfers and Burns affect the sender's balance |
| 36 | + AND canonical = true AND microblock_canonical = true |
| 37 | + GROUP BY sender |
| 38 | + UNION ALL |
| 39 | + SELECT recipient AS address, SUM(amount) AS balance_change |
| 40 | + FROM stx_events |
| 41 | + WHERE asset_event_type_id IN (1, 2) -- Transfers and Mints affect the recipient's balance |
| 42 | + AND canonical = true AND microblock_canonical = true |
| 43 | + GROUP BY recipient |
| 44 | + ), |
| 45 | + net_balances AS ( |
| 46 | + SELECT address, SUM(balance_change) AS balance |
| 47 | + FROM all_balances |
| 48 | + GROUP BY address |
| 49 | + ), |
| 50 | + fees AS ( |
| 51 | + SELECT address, SUM(total_fees) AS total_fees |
| 52 | + FROM ( |
| 53 | + SELECT sender_address AS address, SUM(fee_rate) AS total_fees |
| 54 | + FROM txs |
| 55 | + WHERE canonical = true AND microblock_canonical = true AND sponsored = false |
| 56 | + GROUP BY sender_address |
| 57 | + UNION ALL |
| 58 | + SELECT sponsor_address AS address, SUM(fee_rate) AS total_fees |
| 59 | + FROM txs |
| 60 | + WHERE canonical = true AND microblock_canonical = true AND sponsored = true |
| 61 | + GROUP BY sponsor_address |
| 62 | + ) AS subquery |
| 63 | + GROUP BY address |
| 64 | + ), |
| 65 | + rewards AS ( |
| 66 | + SELECT |
| 67 | + recipient AS address, |
| 68 | + SUM( |
| 69 | + coinbase_amount + tx_fees_anchored + tx_fees_streamed_confirmed + tx_fees_streamed_produced |
| 70 | + ) AS total_rewards |
| 71 | + FROM miner_rewards |
| 72 | + WHERE canonical = true |
| 73 | + GROUP BY recipient |
| 74 | + ), |
| 75 | + all_addresses AS ( |
| 76 | + SELECT address FROM net_balances |
| 77 | + UNION |
| 78 | + SELECT address FROM fees |
| 79 | + UNION |
| 80 | + SELECT address FROM rewards |
| 81 | + ) |
| 82 | + INSERT INTO ft_balances (address, balance, token) |
| 83 | + SELECT |
| 84 | + aa.address, |
| 85 | + COALESCE(nb.balance, 0) - COALESCE(f.total_fees, 0) + COALESCE(r.total_rewards, 0) AS balance, |
| 86 | + 'stx' AS token |
| 87 | + FROM all_addresses aa |
| 88 | + LEFT JOIN net_balances nb ON aa.address = nb.address |
| 89 | + LEFT JOIN fees f ON aa.address = f.address |
| 90 | + LEFT JOIN rewards r ON aa.address = r.address |
| 91 | + `); |
| 92 | + |
| 93 | + // Populate the table with the current FT balances |
| 94 | + pgm.sql(` |
| 95 | + WITH all_balances AS ( |
| 96 | + SELECT sender AS address, asset_identifier, -SUM(amount) AS balance_change |
| 97 | + FROM ft_events |
| 98 | + WHERE asset_event_type_id IN (1, 3) -- Transfers and Burns affect the sender's balance |
| 99 | + AND canonical = true |
| 100 | + AND microblock_canonical = true |
| 101 | + GROUP BY sender, asset_identifier |
| 102 | + UNION ALL |
| 103 | + SELECT recipient AS address, asset_identifier, SUM(amount) AS balance_change |
| 104 | + FROM ft_events |
| 105 | + WHERE asset_event_type_id IN (1, 2) -- Transfers and Mints affect the recipient's balance |
| 106 | + AND canonical = true |
| 107 | + AND microblock_canonical = true |
| 108 | + GROUP BY recipient, asset_identifier |
| 109 | + ), |
| 110 | + net_balances AS ( |
| 111 | + SELECT address, asset_identifier, SUM(balance_change) AS balance |
| 112 | + FROM all_balances |
| 113 | + GROUP BY address, asset_identifier |
| 114 | + ) |
| 115 | + INSERT INTO ft_balances (address, balance, token) |
| 116 | + SELECT address, balance, asset_identifier AS token |
| 117 | + FROM net_balances |
| 118 | + `); |
| 119 | + |
| 120 | +}; |
| 121 | + |
| 122 | +/** @param { import("node-pg-migrate").MigrationBuilder } pgm */ |
| 123 | +exports.down = pgm => { |
| 124 | + pgm.dropTable('ft_balances'); |
| 125 | +}; |
0 commit comments