|
| 1 | +-- Migration 30: Update UNIQUE constraint on universe_leaves table. |
| 2 | +-- ================================================================= |
| 3 | +-- |
| 4 | +-- OVERVIEW: |
| 5 | +-- |
| 6 | +-- This migration modifies the UNIQUE constraint on the universe_leaves table |
| 7 | +-- to allow assets to exist in multiple universe trees simultaneously. We change |
| 8 | +-- from a two-column constraint (minting_point, script_key_bytes) to a three-column |
| 9 | +-- constraint (minting_point, script_key_bytes, leaf_node_namespace). |
| 10 | +-- |
| 11 | +-- PROBLEM STATEMENT: |
| 12 | +-- |
| 13 | +-- In the current schema, the universe_leaves table enforces uniqueness based on |
| 14 | +-- minting_point and script_key_bytes. This design assumes an asset belongs to only |
| 15 | +-- one type of universe tree (transfer or issuance). However, with the introduction |
| 16 | +-- of "ignore" and "burn" universe trees, the same asset might need to exist in |
| 17 | +-- multiple trees simultaneously. |
| 18 | +-- |
| 19 | +-- SOLUTION: |
| 20 | +-- |
| 21 | +-- We expand the unique constraint to include the leaf_node_namespace column. This |
| 22 | +-- additional dimension allows distinguishing between assets based on which universe |
| 23 | +-- tree they belong to, while still preventing duplicates within the same tree. |
| 24 | +-- |
| 25 | +-- MIGRATION STRATEGY: |
| 26 | +-- |
| 27 | +-- Since SQLite has limited ALTER TABLE capabilities and we need to maintain |
| 28 | +-- compatibility with both SQLite and PostgreSQL, we use a table recreation approach: |
| 29 | +-- |
| 30 | +-- 1. Handle foreign key dependencies (back up and remove federation_proof_sync_log). |
| 31 | +-- 2. Create a new table with the updated constraint. |
| 32 | +-- 3. Copy existing data. |
| 33 | +-- 4. Replace the old table with the new one. |
| 34 | +-- 5. Restore dependent tables with proper references. |
| 35 | +-- |
| 36 | +-- This approach works with both database engines while preserving data integrity. |
| 37 | +-- |
| 38 | + |
| 39 | +-- ==== PHASE 1: HANDLE FOREIGN KEY DEPENDENCIES ==== |
| 40 | +-- Before we can drop the universe_leaves table, we need to temporarily remove |
| 41 | +-- any foreign key references pointing to it. The federation_proof_sync_log table |
| 42 | +-- has a foreign key to universe_leaves.id that would prevent dropping the table. |
| 43 | + |
| 44 | +-- Create a temporary backup table for federation_proof_sync_log. |
| 45 | +CREATE TABLE new_federation_proof_sync_log ( |
| 46 | + id INTEGER PRIMARY KEY, |
| 47 | + status TEXT NOT NULL CHECK(status IN ('pending', 'complete')), |
| 48 | + timestamp TIMESTAMP NOT NULL, |
| 49 | + attempt_counter BIGINT NOT NULL DEFAULT 0, |
| 50 | + sync_direction TEXT NOT NULL CHECK(sync_direction IN ('push', 'pull')), |
| 51 | + proof_leaf_id BIGINT NOT NULL, -- FK constraint intentionally omitted for now. |
| 52 | + universe_root_id BIGINT NOT NULL REFERENCES universe_roots(id), |
| 53 | + servers_id BIGINT NOT NULL REFERENCES universe_servers(id) |
| 54 | +); |
| 55 | + |
| 56 | + |
| 57 | +-- Backup all existing federation_proof_sync_log data. |
| 58 | +INSERT INTO new_federation_proof_sync_log |
| 59 | +SELECT * FROM federation_proof_sync_log; |
| 60 | + |
| 61 | +-- Remove the table with the foreign key constraint to universe_leaves. |
| 62 | +-- This allows us to safely drop universe_leaves later. |
| 63 | +DROP TABLE federation_proof_sync_log; |
| 64 | +DROP INDEX IF EXISTS federation_proof_sync_log_unique_index_proof_leaf_id_servers_id; |
| 65 | + |
| 66 | +-- ==== PHASE 2: CREATE NEW TABLE WITH UPDATED CONSTRAINT ==== |
| 67 | +-- Create a new universe_leaves table with the enhanced 3-column unique constraint. |
| 68 | +CREATE TABLE new_universe_leaves ( |
| 69 | + id INTEGER PRIMARY KEY, |
| 70 | + asset_genesis_id BIGINT NOT NULL REFERENCES genesis_assets(gen_asset_id), |
| 71 | + minting_point BLOB NOT NULL, |
| 72 | + script_key_bytes BLOB NOT NULL CHECK(LENGTH(script_key_bytes) = 32), |
| 73 | + universe_root_id BIGINT NOT NULL REFERENCES universe_roots(id), |
| 74 | + leaf_node_key BLOB, |
| 75 | + leaf_node_namespace VARCHAR NOT NULL, |
| 76 | + UNIQUE(minting_point, script_key_bytes, leaf_node_namespace) |
| 77 | +); |
| 78 | + |
| 79 | +-- ==== PHASE 3: MIGRATE DATA ==== |
| 80 | +-- Copy all existing data from the original table to the new one. |
| 81 | +INSERT INTO new_universe_leaves ( |
| 82 | + id, |
| 83 | + asset_genesis_id, |
| 84 | + minting_point, |
| 85 | + script_key_bytes, |
| 86 | + universe_root_id, |
| 87 | + leaf_node_key, |
| 88 | + leaf_node_namespace |
| 89 | +) |
| 90 | +SELECT |
| 91 | + id, |
| 92 | + asset_genesis_id, |
| 93 | + minting_point, |
| 94 | + script_key_bytes, |
| 95 | + universe_root_id, |
| 96 | + leaf_node_key, |
| 97 | + leaf_node_namespace |
| 98 | +FROM universe_leaves; |
| 99 | + |
| 100 | +-- ==== PHASE 4: TABLE REPLACEMENT ==== |
| 101 | +-- Now that data is safely copied, remove the old table. |
| 102 | +DROP TABLE universe_leaves; |
| 103 | + |
| 104 | +-- Rename the new table to replace the old one. |
| 105 | +ALTER TABLE new_universe_leaves RENAME TO universe_leaves; |
| 106 | + |
| 107 | +-- Recreate indexes that existed on the original table. |
| 108 | +CREATE INDEX IF NOT EXISTS universe_leaves_key_idx ON universe_leaves(leaf_node_key); |
| 109 | +CREATE INDEX IF NOT EXISTS universe_leaves_namespace ON universe_leaves(leaf_node_namespace); |
| 110 | + |
| 111 | +-- ==== PHASE 5: RESTORE DEPENDENT TABLES ==== |
| 112 | +-- Recreate the federation_proof_sync_log table with proper foreign key references. |
| 113 | +CREATE TABLE federation_proof_sync_log ( |
| 114 | + id INTEGER PRIMARY KEY, |
| 115 | + |
| 116 | + -- The status of the proof sync attempt. |
| 117 | + status TEXT NOT NULL CHECK(status IN ('pending', 'complete')), |
| 118 | + |
| 119 | + -- The timestamp of when the log entry for the associated proof was last |
| 120 | + -- updated. |
| 121 | + timestamp TIMESTAMP NOT NULL, |
| 122 | + |
| 123 | + -- The number of attempts that have been made to sync the proof. |
| 124 | + attempt_counter BIGINT NOT NULL DEFAULT 0, |
| 125 | + |
| 126 | + -- The direction of the proof sync attempt. |
| 127 | + sync_direction TEXT NOT NULL CHECK(sync_direction IN ('push', 'pull')), |
| 128 | + |
| 129 | + -- The ID of the subject proof leaf. |
| 130 | + proof_leaf_id BIGINT NOT NULL REFERENCES universe_leaves(id), |
| 131 | + |
| 132 | + -- The ID of the universe that the proof leaf belongs to. |
| 133 | + universe_root_id BIGINT NOT NULL REFERENCES universe_roots(id), |
| 134 | + |
| 135 | + -- The ID of the server that the proof will be/was synced to. |
| 136 | + servers_id BIGINT NOT NULL REFERENCES universe_servers(id) |
| 137 | +); |
| 138 | + |
| 139 | +-- Restore valid federation_proof_sync_log data. |
| 140 | +-- Only reinsert records that reference existing leaves in the universe_leaves table. |
| 141 | +INSERT INTO federation_proof_sync_log |
| 142 | +SELECT * FROM new_federation_proof_sync_log |
| 143 | +WHERE proof_leaf_id IN (SELECT id FROM universe_leaves); |
| 144 | + |
| 145 | +-- Clean up by dropping the temporary table. |
| 146 | +DROP TABLE new_federation_proof_sync_log; |
| 147 | + |
| 148 | +-- Re-create the unique index on table new_federation_proof_sync_log. |
| 149 | +CREATE UNIQUE INDEX federation_proof_sync_log_unique_index_proof_leaf_id_servers_id |
| 150 | +ON federation_proof_sync_log ( |
| 151 | + sync_direction, |
| 152 | + proof_leaf_id, |
| 153 | + universe_root_id, |
| 154 | + servers_id |
| 155 | +); |
0 commit comments