Files
crowd-funder-from-jason/src/db-sql/migration.ts
Matthew Raymer 704e495f5d refactor(db): consolidate database migrations from 6 to 3
- Add missing migrations table creation to 001_initial migration
- Consolidate migrations 003-006 into single 003_active_did_separation migration
- Rename migration for better clarity and logical grouping
- Preserve all original SQL operations and data integrity constraints
- Reduce migration complexity while maintaining functionality

This consolidation improves maintainability by grouping related schema changes
into logical atomic operations, reducing the total migration count by 50%.
2025-09-05 04:57:11 +00:00

211 lines
8.0 KiB
TypeScript

import {
registerMigration,
runMigrations as runMigrationsService,
} from "../services/migrationService";
import { DEFAULT_ENDORSER_API_SERVER } from "@/constants/app";
import { arrayBufferToBase64 } from "@/libs/crypto";
import { logger } from "@/utils/logger";
// Generate a random secret for the secret table
// It's not really secure to maintain the secret next to the user's data.
// However, until we have better hooks into a real wallet or reliable secure
// storage, we'll do this for user convenience. As they sign more records
// and integrate with more people, they'll value it more and want to be more
// secure, so we'll prompt them to take steps to back it up, properly encrypt,
// etc. At the beginning, we'll prompt for a password, then we'll prompt for a
// PWA so it's not in a browser... and then we hope to be integrated with a
// real wallet or something else more secure.
// One might ask: why encrypt at all? We figure a basic encryption is better
// than none. Plus, we expect to support their own password or keystore or
// external wallet as better signing options in the future, so it's gonna be
// important to have the structure where each account access might require
// user action.
// (Once upon a time we stored the secret in localStorage, but it frequently
// got erased, even though the IndexedDB still had the identity data. This
// ended up throwing lots of errors to the user... and they'd end up in a state
// where they couldn't take action because they couldn't unlock that identity.)
const randomBytes = crypto.getRandomValues(new Uint8Array(32));
const secretBase64 = arrayBufferToBase64(randomBytes);
// Each migration can include multiple SQL statements (with semicolons)
const MIGRATIONS = [
{
name: "001_initial",
sql: `
CREATE TABLE IF NOT EXISTS accounts (
id INTEGER PRIMARY KEY AUTOINCREMENT,
dateCreated TEXT NOT NULL,
derivationPath TEXT,
did TEXT NOT NULL,
identityEncrBase64 TEXT, -- encrypted & base64-encoded
mnemonicEncrBase64 TEXT, -- encrypted & base64-encoded
passkeyCredIdHex TEXT,
publicKeyHex TEXT NOT NULL
);
CREATE INDEX IF NOT EXISTS idx_accounts_did ON accounts(did);
CREATE TABLE IF NOT EXISTS secret (
id INTEGER PRIMARY KEY AUTOINCREMENT,
secretBase64 TEXT NOT NULL
);
INSERT INTO secret (id, secretBase64) VALUES (1, '${secretBase64}');
CREATE TABLE IF NOT EXISTS settings (
id INTEGER PRIMARY KEY AUTOINCREMENT,
accountDid TEXT,
activeDid TEXT,
apiServer TEXT,
filterFeedByNearby BOOLEAN,
filterFeedByVisible BOOLEAN,
finishedOnboarding BOOLEAN,
firstName TEXT,
hideRegisterPromptOnNewContact BOOLEAN,
isRegistered BOOLEAN,
lastName TEXT,
lastAckedOfferToUserJwtId TEXT,
lastAckedOfferToUserProjectsJwtId TEXT,
lastNotifiedClaimId TEXT,
lastViewedClaimId TEXT,
notifyingNewActivityTime TEXT,
notifyingReminderMessage TEXT,
notifyingReminderTime TEXT,
partnerApiServer TEXT,
passkeyExpirationMinutes INTEGER,
profileImageUrl TEXT,
searchBoxes TEXT, -- Stored as JSON string
showContactGivesInline BOOLEAN,
showGeneralAdvanced BOOLEAN,
showShortcutBvc BOOLEAN,
vapid TEXT,
warnIfProdServer BOOLEAN,
warnIfTestServer BOOLEAN,
webPushServer TEXT
);
CREATE INDEX IF NOT EXISTS idx_settings_accountDid ON settings(accountDid);
INSERT INTO settings (id, apiServer) VALUES (1, '${DEFAULT_ENDORSER_API_SERVER}');
CREATE TABLE IF NOT EXISTS contacts (
id INTEGER PRIMARY KEY AUTOINCREMENT,
did TEXT NOT NULL,
name TEXT,
contactMethods TEXT, -- Stored as JSON string
nextPubKeyHashB64 TEXT,
notes TEXT,
profileImageUrl TEXT,
publicKeyBase64 TEXT,
seesMe BOOLEAN,
registered BOOLEAN
);
CREATE INDEX IF NOT EXISTS idx_contacts_did ON contacts(did);
CREATE INDEX IF NOT EXISTS idx_contacts_name ON contacts(name);
CREATE TABLE IF NOT EXISTS logs (
date TEXT NOT NULL,
message TEXT NOT NULL
);
CREATE TABLE IF NOT EXISTS temp (
id TEXT PRIMARY KEY,
blobB64 TEXT
);
CREATE TABLE IF NOT EXISTS migrations (
name TEXT PRIMARY KEY,
applied_at TEXT NOT NULL DEFAULT (datetime('now'))
);
`,
},
{
name: "002_add_iViewContent_to_contacts",
sql: `
ALTER TABLE contacts ADD COLUMN iViewContent BOOLEAN DEFAULT TRUE;
`,
},
{
name: "003_active_did_separation",
sql: `
-- CONSOLIDATED MIGRATION: Combines original migrations 003, 004, 005, and 006
-- This migration handles the complete separation of activeDid from settings
-- and establishes proper data integrity constraints
-- Create new active_identity table with proper constraints
CREATE TABLE IF NOT EXISTS active_identity (
id INTEGER PRIMARY KEY CHECK (id = 1),
activeDid TEXT NOT NULL,
lastUpdated TEXT NOT NULL DEFAULT (datetime('now')),
FOREIGN KEY (activeDid) REFERENCES accounts(did) ON DELETE CASCADE
);
-- Add performance indexes
CREATE INDEX IF NOT EXISTS idx_active_identity_activeDid ON active_identity(activeDid);
CREATE UNIQUE INDEX IF NOT EXISTS idx_active_identity_single_record ON active_identity(id);
-- Insert default record (will be updated during migration)
INSERT OR IGNORE INTO active_identity (id, activeDid, lastUpdated) VALUES (1, '', datetime('now'));
-- MIGRATE EXISTING DATA: Copy activeDid from settings to active_identity
-- This prevents data loss when migration runs on existing databases
UPDATE active_identity
SET activeDid = (SELECT activeDid FROM settings WHERE id = 1),
lastUpdated = datetime('now')
WHERE id = 1
AND EXISTS (SELECT 1 FROM settings WHERE id = 1 AND activeDid IS NOT NULL AND activeDid != '');
-- Remove activeDid column from settings table (moved to active_identity)
-- Note: SQLite doesn't support DROP COLUMN in older versions
-- This migration will be skipped if DROP COLUMN is not supported
-- The activeDid column will remain but won't be used by the application
ALTER TABLE settings DROP COLUMN activeDid;
-- Eliminate MASTER_SETTINGS_KEY concept - remove confusing id=1 row
-- This creates clean separation: active_identity for current identity, settings for identity config
DELETE FROM settings WHERE id = 1 AND accountDid IS NULL;
-- Reset auto-increment to start from 1 again
DELETE FROM sqlite_sequence WHERE name = 'settings';
-- Add unique constraint to prevent duplicate accountDid values
-- This ensures data integrity: each identity can only have one settings record
DELETE FROM settings
WHERE id NOT IN (
SELECT MAX(id)
FROM settings
WHERE accountDid IS NOT NULL
GROUP BY accountDid
) AND accountDid IS NOT NULL;
CREATE UNIQUE INDEX IF NOT EXISTS idx_settings_accountDid_unique ON settings(accountDid);
`,
},
];
/**
* @param sqlExec - A function that executes a SQL statement and returns the result
* @param extractMigrationNames - A function that extracts the names (string array) from "select name from migrations"
*/
export async function runMigrations<T>(
sqlExec: (sql: string, params?: unknown[]) => Promise<void>,
sqlQuery: (sql: string, params?: unknown[]) => Promise<T>,
extractMigrationNames: (result: T) => Set<string>,
): Promise<void> {
logger.info("[Migration] Starting database migrations");
for (const migration of MIGRATIONS) {
logger.debug("[Migration] Registering migration:", migration.name);
registerMigration(migration);
}
logger.info("[Migration] Running migration service");
await runMigrationsService(sqlExec, sqlQuery, extractMigrationNames);
logger.info("[Migration] Database migrations completed");
}