|
| 1 | +"use strict"; |
| 2 | + |
| 3 | +module.exports = { |
| 4 | + up: async (queryInterface, Sequelize) => { |
| 5 | + await queryInterface.createTable("AggsUTXOs", { |
| 6 | + id: { |
| 7 | + allowNull: false, |
| 8 | + autoIncrement: true, |
| 9 | + primaryKey: true, |
| 10 | + type: Sequelize.BIGINT |
| 11 | + }, |
| 12 | + address: { |
| 13 | + allowNull: false, |
| 14 | + type: Sequelize.STRING |
| 15 | + }, |
| 16 | + assetType: { |
| 17 | + allowNull: false, |
| 18 | + type: Sequelize.STRING |
| 19 | + }, |
| 20 | + totalAssetQuantity: { |
| 21 | + allowNull: false, |
| 22 | + type: Sequelize.BIGINT, |
| 23 | + defaultValue: 0 |
| 24 | + }, |
| 25 | + utxoQuantity: { |
| 26 | + allowNull: false, |
| 27 | + type: Sequelize.BIGINT, |
| 28 | + defaultValue: 0 |
| 29 | + }, |
| 30 | + createdAt: { |
| 31 | + allowNull: false, |
| 32 | + type: Sequelize.DATE |
| 33 | + }, |
| 34 | + updatedAt: { |
| 35 | + allowNull: false, |
| 36 | + type: Sequelize.DATE |
| 37 | + } |
| 38 | + }); |
| 39 | + |
| 40 | + await queryInterface.addIndex("AggsUTXOs", { |
| 41 | + fields: ["address", "assetType"], |
| 42 | + unique: true |
| 43 | + }); |
| 44 | + |
| 45 | + await queryInterface.sequelize.query(` |
| 46 | + CREATE FUNCTION utxos_trigger_function() RETURNS trigger |
| 47 | + LANGUAGE plpgsql |
| 48 | + as |
| 49 | + $$ |
| 50 | + BEGIN |
| 51 | + IF (TG_OP = 'INSERT') THEN |
| 52 | + IF NEW."usedBlockNumber" IS NULL THEN |
| 53 | + INSERT INTO "AggsUTXOs"("assetType", address, "totalAssetQuantity", "utxoQuantity", "createdAt", "updatedAt") VALUES(NEW."assetType", NEW.address, NEW.quantity, 1, NOW(), NOW()) |
| 54 | + ON CONFLICT ("assetType", "address") DO UPDATE SET "totalAssetQuantity"="AggsUTXOs"."totalAssetQuantity"+NEW."quantity", "utxoQuantity"="AggsUTXOs"."utxoQuantity"+1; |
| 55 | + END IF; |
| 56 | + return NEW; |
| 57 | + ELSEIF (TG_OP = 'UPDATE') THEN |
| 58 | + IF OLD."usedBlockNumber" IS NULL THEN |
| 59 | + UPDATE "AggsUTXOs" SET "totalAssetQuantity"="totalAssetQuantity"-OLD.quantity, "utxoQuantity"="utxoQuantity"-1, "updatedAt"=NOW() WHERE "AggsUTXOs".address=OLD.address AND "AggsUTXOs"."assetType"=OLD."assetType"; |
| 60 | + END IF; |
| 61 | + IF NEW."usedBlockNumber" IS NULL THEN |
| 62 | + INSERT INTO "AggsUTXOs"("assetType", address, "totalAssetQuantity", "utxoQuantity", "createdAt", "updatedAt") VALUES(NEW."assetType", NEW.address, NEW.quantity, 1, NOW(), NOW()) |
| 63 | + ON CONFLICT ("assetType", "address") DO UPDATE SET "totalAssetQuantity"="AggsUTXOs"."totalAssetQuantity"+NEW.quantity, "utxoQuantity"="AggsUTXOs"."utxoQuantity"+1; |
| 64 | + END IF; |
| 65 | + RETURN NEW; |
| 66 | + ELSEIF (TG_OP = 'DELETE') THEN |
| 67 | + IF OLD."usedBlockNumber" IS NULL THEN |
| 68 | + UPDATE "AggsUTXOs" SET "totalAssetQuantity"="totalAssetQuantity"-OLD.quantity, "utxoQuantity"="utxoQuantity"-1, "updatedAt"=NOW() WHERE "AggsUTXOs".address=OLD.address AND "AggsUTXOs"."assetType"=OLD."assetType"; |
| 69 | + END IF; |
| 70 | + return OLD; |
| 71 | + END IF; |
| 72 | + END; |
| 73 | + $$;`); |
| 74 | + await queryInterface.sequelize.query(` |
| 75 | + CREATE TRIGGER utxos_trigger |
| 76 | + AFTER INSERT OR UPDATE OR DELETE |
| 77 | + ON "UTXOs" |
| 78 | + FOR EACH ROW |
| 79 | + EXECUTE PROCEDURE utxos_trigger_function() |
| 80 | + `); |
| 81 | + |
| 82 | + await queryInterface.sequelize.query(` |
| 83 | + INSERT INTO "AggsUTXOs"("assetType", "address", "totalAssetQuantity", "utxoQuantity", "createdAt", "updatedAt") SELECT "assetType", "address", SUM("quantity") as "totalAssetQuantity", COUNT(*) as "utxoQuantity", NOW(), NOW() FROM "UTXOs" GROUP BY "assetType", "address" |
| 84 | + `); |
| 85 | + }, |
| 86 | + |
| 87 | + down: async (queryInterface, Sequelize) => { |
| 88 | + await queryInterface.dropTable("AggsUTXOs"); |
| 89 | + await queryInterface.sequelize.query( |
| 90 | + `DROP TRIGGER "utxos_trigger" ON "UTXOs"` |
| 91 | + ); |
| 92 | + await queryInterface.sequelize.query( |
| 93 | + "DROP FUNCTION utxos_trigger_function()" |
| 94 | + ); |
| 95 | + } |
| 96 | +}; |
0 commit comments