-
Notifications
You must be signed in to change notification settings - Fork 116
Commit
This commit does not belong to any branch on this repository, and may belong to a fork outside of the repository.
Merge pull request #980 from lightninglabs/unique-key-fix
tapdb: remove duplicate assets before adding unique index
- Loading branch information
Showing
3 changed files
with
218 additions
and
3 deletions.
There are no files selected for viewing
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -1,4 +1,98 @@ | ||
-- Step 1: If the assets were spent, some of the duplicates might not have been | ||
-- updated on that flag. To make sure we can properly group on the spent flag | ||
-- below, we now update all assets that are spent. | ||
UPDATE assets | ||
SET spent = true | ||
WHERE asset_id IN (SELECT a.asset_id | ||
FROM assets a | ||
JOIN managed_utxos mu | ||
ON a.anchor_utxo_id = mu.utxo_id | ||
JOIN chain_txns ct | ||
ON mu.txn_id = ct.txn_id | ||
LEFT JOIN asset_transfer_inputs ati | ||
ON ati.anchor_point = mu.outpoint | ||
WHERE a.spent = false | ||
AND ati.input_id IS NOT NULL); | ||
|
||
-- Step 2: Create a temporary table to store the minimum asset_id for each | ||
-- unique combination. | ||
CREATE TABLE tmp_min_assets AS | ||
SELECT MIN(asset_id) AS min_asset_id, | ||
genesis_id, | ||
script_key_id, | ||
amount, | ||
anchor_utxo_id, | ||
spent | ||
FROM assets | ||
GROUP BY genesis_id, script_key_id, amount, anchor_utxo_id, spent; | ||
|
||
-- Step 3: Create a mapping table to track old and new asset_ids. | ||
CREATE TABLE tmp_asset_id_mapping AS | ||
SELECT a.asset_id AS old_asset_id, | ||
tmp.min_asset_id AS new_asset_id | ||
FROM assets a | ||
JOIN tmp_min_assets tmp | ||
ON a.genesis_id = tmp.genesis_id | ||
AND a.script_key_id = tmp.script_key_id | ||
AND a.amount = tmp.amount | ||
AND a.anchor_utxo_id = tmp.anchor_utxo_id | ||
AND a.spent = tmp.spent; | ||
|
||
-- Step 4: To make the next step possible, we need to disable a unique index on | ||
-- the asset_witnesses table. We'll re-create it later. | ||
DROP INDEX IF EXISTS asset_witnesses_asset_id_witness_index_unique; | ||
|
||
-- Step 5: Update the asset_witnesses and asset_proofs tables to reference the | ||
-- new asset_ids. | ||
UPDATE asset_witnesses | ||
SET asset_id = tmp_asset_id_mapping.new_asset_id | ||
FROM tmp_asset_id_mapping | ||
WHERE asset_witnesses.asset_id = tmp_asset_id_mapping.old_asset_id; | ||
|
||
-- For the proofs we need skip re-assigning them to the asset that we're going | ||
-- to keep if it already has a proof. This is because the unique index on the | ||
-- asset_proofs table would prevent us from doing so. And we can't disable the | ||
-- unique index, because it is an unnamed/inline index. | ||
UPDATE asset_proofs | ||
SET asset_id = filtered_mapping.new_asset_id | ||
FROM ( | ||
SELECT MIN(old_asset_id) AS old_asset_id, new_asset_id | ||
FROM asset_proofs | ||
JOIN tmp_asset_id_mapping | ||
ON asset_proofs.asset_id = tmp_asset_id_mapping.old_asset_id | ||
GROUP BY new_asset_id) AS filtered_mapping | ||
WHERE asset_proofs.asset_id = filtered_mapping.old_asset_id; | ||
|
||
-- Step 6: Remove duplicates from the asset_witnesses table. | ||
DELETE | ||
FROM asset_witnesses | ||
WHERE witness_id NOT IN (SELECT min(witness_id) | ||
FROM asset_witnesses | ||
GROUP BY asset_id, witness_index); | ||
|
||
-- Step 7: Re-enable the unique index on the asset_witnesses table. | ||
CREATE UNIQUE INDEX asset_witnesses_asset_id_witness_index_unique | ||
ON asset_witnesses ( | ||
asset_id, witness_index | ||
); | ||
|
||
-- Step 8: Delete any duplicate proofs. | ||
DELETE | ||
FROM asset_proofs | ||
WHERE asset_id NOT IN (SELECT min_asset_id FROM tmp_min_assets); | ||
|
||
-- Step 9: Delete the duplicates from the assets table. This will then also | ||
-- delete dangling asset_witnesses. | ||
DELETE | ||
FROM assets | ||
WHERE asset_id NOT IN (SELECT min_asset_id FROM tmp_min_assets); | ||
|
||
-- Step 10: Clean up temporary tables. | ||
DROP TABLE IF EXISTS tmp_min_assets; | ||
DROP TABLE IF EXISTS tmp_asset_id_mapping; | ||
|
||
-- Step 11: Create the unique index on the assets table. | ||
CREATE UNIQUE INDEX assets_genesis_id_script_key_id_anchor_utxo_id_unique | ||
ON assets ( | ||
genesis_id, script_key_id, anchor_utxo_id | ||
); | ||
ON assets ( | ||
genesis_id, script_key_id, anchor_utxo_id | ||
); |
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -0,0 +1,48 @@ | ||
-- This dummy data inserts duplicate assets, including their witnesses. The | ||
-- migration script with number 20 should clean the duplicates up. | ||
INSERT INTO chain_txns VALUES(1,X'a1594fc379308b2a209f6d0bdb8602e9f87cf71fc232c69032b9a5fed28f9331',1980,X'02000000000101022cd51ca4d850c5f71ceedf7c50a08ff82d66612b22f631eac95e6b52cbbd2d0000000000ffffffff02e80300000000000022512018ac5a65a0d12e7846c89d24705e2697b1da14627978ba8db24bdbce21fc2aa85cd5f5050000000022512030263d67b4275144b2b00921d220a1311b9a4465fa656ba7d5754b421cb4308402483045022100fa32af97cab8a765dc347c3ff57b14f9810b6dbfc4d02727fb099d1ed875660602204cb66f3bbd92925707158b4aa67338c50a9ffddceb023875eb82b78b3967e007012102eb9cd2a22fd11c40823cb7b0f0fba4156138af69cf73c0644be54f4d46ba480700000000',441,X'4295613d85ccbc455159eb4ddd1e266ca10041d3c75726286b7dfeb3132c9c4f',1); | ||
|
||
INSERT INTO genesis_points VALUES(1,X'022cd51ca4d850c5f71ceedf7c50a08ff82d66612b22f631eac95e6b52cbbd2d00000000',1); | ||
|
||
INSERT INTO assets_meta VALUES(1,X'2b990b7adb1faf51ccb9b1c73bc5e73926db39cdec8906d4fd3c6c423a3c9821',X'736f6d65206d65746164617461',0); | ||
|
||
INSERT INTO genesis_assets VALUES(1,X'add7d0d7cc37e58a7c0d8ad40b6904050d2baa25a1829f00689c4b27b524dd04','itestbuxx-collectible',1,0,1,1); | ||
INSERT INTO genesis_assets VALUES(2,X'ffffd0d7cc37e58a7c0d8ad40b6904050d2baa25a1829f00689c4b27b524dd04','itestbuxx-collectible2',1,0,1,1); | ||
|
||
INSERT INTO internal_keys VALUES(1,X'02827d74858d152da1fae12010ad8d3c46b595c2d4480512a6575925424617124f',212,0); | ||
INSERT INTO internal_keys VALUES(2,X'03efbcf2878876bae81ca9a7f6476764d2da38d565b9fb2b691e7bb22fd99f9e5e',212,2); | ||
|
||
INSERT INTO managed_utxos VALUES(1,X'a1594fc379308b2a209f6d0bdb8602e9f87cf71fc232c69032b9a5fed28f933100000000',1000,1,X'1dd3e2cf0bbbee32832c4deb57bbae58779fa599be0b8eb1f61e8c624157e2fa',NULL,X'1dd3e2cf0bbbee32832c4deb57bbae58779fa599be0b8eb1f61e8c624157e2fa',1,NULL,NULL,0); | ||
|
||
INSERT INTO script_keys VALUES(1,2,X'029c571fffcac1a1a7cd3372bd202ad8562f28e48b90f8a4eb714eca062f576ee6',NULL,true); | ||
INSERT INTO script_keys VALUES(2,2,X'039c571fffcac1a1a7cd3372bd202ad8562f28e48b90f8a4eb714eca062f576ee6',NULL,true); | ||
|
||
-- We have some duplicate assets, both having witnesses. | ||
INSERT INTO assets VALUES(1,1,0,1,NULL,0,1,0,0,NULL,NULL,1,false); | ||
INSERT INTO assets VALUES(2,1,0,1,NULL,0,1,0,0,NULL,NULL,1,false); | ||
|
||
INSERT INTO asset_witnesses VALUES(1,1,X'a1594fc379308b2a209f6d0bdb8602e9f87cf71fc232c69032b9a5fed28f933100000000',X'add7d0d7cc37e58a7c0d8ad40b6904050d2baa25a1829f00689c4b27b524dd04',X'02827d74858d152da1fae12010ad8d3c46b595c2d4480512a6575925424617124f',X'0101aa',NULL, 0); | ||
INSERT INTO asset_witnesses VALUES(2,1,X'a1594fc379308b2a209f6d0bdb8602e9f87cf71fc232c69032b9a5fed28f933101000000',X'add7d0d7cc37e58a7c0d8ad40b6904050d2baa25a1829f00689c4b27b524dd04',X'02827d74858d152da1fae12010ad8d3c46b595c2d4480512a6575925424617124f',X'0101bb',NULL, 1); | ||
|
||
INSERT INTO asset_witnesses VALUES(3,2,X'a1594fc379308b2a209f6d0bdb8602e9f87cf71fc232c69032b9a5fed28f933100000000',X'add7d0d7cc37e58a7c0d8ad40b6904050d2baa25a1829f00689c4b27b524dd04',X'02827d74858d152da1fae12010ad8d3c46b595c2d4480512a6575925424617124f',X'0101cc',NULL, 0); | ||
INSERT INTO asset_witnesses VALUES(4,2,X'a1594fc379308b2a209f6d0bdb8602e9f87cf71fc232c69032b9a5fed28f933101000000',X'add7d0d7cc37e58a7c0d8ad40b6904050d2baa25a1829f00689c4b27b524dd04',X'02827d74858d152da1fae12010ad8d3c46b595c2d4480512a6575925424617124f',X'0101dd',NULL, 1); | ||
|
||
INSERT INTO asset_proofs VALUES(1,1,X'aaaa'); | ||
|
||
INSERT INTO asset_proofs VALUES(2,2,X'cccc'); | ||
|
||
-- And then a batch of asset duplicates where only one of the duplicates that | ||
-- we're not going to keep has a witness. | ||
INSERT INTO assets VALUES(3,2,0,2,NULL,0,1,0,0,NULL,NULL,1,true); | ||
INSERT INTO assets VALUES(4,2,0,2,NULL,0,1,0,0,NULL,NULL,1,true); | ||
INSERT INTO assets VALUES(5,2,0,2,NULL,0,1,0,0,NULL,NULL,1,true); | ||
|
||
INSERT INTO asset_witnesses VALUES(5,5,X'a1594fc379308b2a209f6d0bdb8602e9f87cf71fc232c69032b9a5fed28f933100000000',X'add7d0d7cc37e58a7c0d8ad40b6904050d2baa25a1829f00689c4b27b524dd04',X'02827d74858d152da1fae12010ad8d3c46b595c2d4480512a6575925424617124f',X'0101cc',NULL, 0); | ||
INSERT INTO asset_witnesses VALUES(6,5,X'a1594fc379308b2a209f6d0bdb8602e9f87cf71fc232c69032b9a5fed28f933101000000',X'add7d0d7cc37e58a7c0d8ad40b6904050d2baa25a1829f00689c4b27b524dd04',X'02827d74858d152da1fae12010ad8d3c46b595c2d4480512a6575925424617124f',X'0101dd',NULL, 1); | ||
|
||
INSERT INTO asset_witnesses VALUES(7,4,X'a1594fc379308b2a209f6d0bdb8602e9f87cf71fc232c69032b9a5fed28f933100000000',X'add7d0d7cc37e58a7c0d8ad40b6904050d2baa25a1829f00689c4b27b524dd04',X'02827d74858d152da1fae12010ad8d3c46b595c2d4480512a6575925424617124f',X'0101ee',NULL, 0); | ||
INSERT INTO asset_witnesses VALUES(8,4,X'a1594fc379308b2a209f6d0bdb8602e9f87cf71fc232c69032b9a5fed28f933101000000',X'add7d0d7cc37e58a7c0d8ad40b6904050d2baa25a1829f00689c4b27b524dd04',X'02827d74858d152da1fae12010ad8d3c46b595c2d4480512a6575925424617124f',X'0101ff',NULL, 1); | ||
|
||
INSERT INTO asset_proofs VALUES(3,4,X'eeee'); | ||
|
||
INSERT INTO asset_proofs VALUES(4,5,X'eeee'); |