Files
crowd-funder-for-time-pwa/doc/dexie-to-sqlite-mapping.md
Matthew Raymer a580ce775d feat: Add comprehensive database migration service for Dexie to SQLite
- Add migrationService.ts with functions to compare and transfer data between Dexie and SQLite
- Implement data comparison with detailed difference analysis (added/modified/missing)
- Add contact migration with overwrite options and error handling
- Add settings migration focusing on key user fields (firstName, isRegistered, profileImageUrl, showShortcutBvc, searchBoxes)
- Include YAML export functionality for data inspection
- Add comprehensive JSDoc documentation with examples and usage instructions
- Support both INSERT and UPDATE operations with parameterized SQL generation
- Include detailed logging and error reporting for migration operations

This service enables safe migration of user data from the legacy Dexie (IndexedDB)
database to the new SQLite implementation, with full comparison capabilities
and rollback safety through detailed reporting.
2025-06-18 10:54:32 +00:00

8.9 KiB

Dexie to absurd-sql Mapping Guide

Schema Mapping

Current Dexie Schema

// Current Dexie schema
const db = new Dexie('TimeSafariDB');

db.version(1).stores({
  accounts: 'did, publicKeyHex, createdAt, updatedAt',
  settings: 'key, value, updatedAt',
  contacts: 'id, did, name, createdAt, updatedAt'
});

New SQLite Schema

-- New SQLite schema
CREATE TABLE accounts (
  did TEXT PRIMARY KEY,
  public_key_hex TEXT NOT NULL,
  created_at INTEGER NOT NULL,
  updated_at INTEGER NOT NULL
);

CREATE TABLE settings (
  key TEXT PRIMARY KEY,
  value TEXT NOT NULL,
  updated_at INTEGER NOT NULL
);

CREATE TABLE contacts (
  id TEXT PRIMARY KEY,
  did TEXT NOT NULL,
  name TEXT,
  created_at INTEGER NOT NULL,
  updated_at INTEGER NOT NULL,
  FOREIGN KEY (did) REFERENCES accounts(did)
);

-- Indexes for performance
CREATE INDEX idx_accounts_created_at ON accounts(created_at);
CREATE INDEX idx_contacts_did ON contacts(did);
CREATE INDEX idx_settings_updated_at ON settings(updated_at);

Query Mapping

1. Account Operations

Get Account by DID

// Dexie
const account = await db.accounts.get(did);

// absurd-sql
const result = await db.exec(`
  SELECT * FROM accounts WHERE did = ?
`, [did]);
const account = result[0]?.values[0];

Get All Accounts

// Dexie
const accounts = await db.accounts.toArray();

// absurd-sql
const result = await db.exec(`
  SELECT * FROM accounts ORDER BY created_at DESC
`);
const accounts = result[0]?.values || [];

Add Account

// Dexie
await db.accounts.add({
  did,
  publicKeyHex,
  createdAt: Date.now(),
  updatedAt: Date.now()
});

// absurd-sql
await db.run(`
  INSERT INTO accounts (did, public_key_hex, created_at, updated_at)
  VALUES (?, ?, ?, ?)
`, [did, publicKeyHex, Date.now(), Date.now()]);

Update Account

// Dexie
await db.accounts.update(did, {
  publicKeyHex,
  updatedAt: Date.now()
});

// absurd-sql
await db.run(`
  UPDATE accounts
  SET public_key_hex = ?, updated_at = ?
  WHERE did = ?
`, [publicKeyHex, Date.now(), did]);

2. Settings Operations

Get Setting

// Dexie
const setting = await db.settings.get(key);

// absurd-sql
const result = await db.exec(`
  SELECT * FROM settings WHERE key = ?
`, [key]);
const setting = result[0]?.values[0];

Set Setting

// Dexie
await db.settings.put({
  key,
  value,
  updatedAt: Date.now()
});

// absurd-sql
await db.run(`
  INSERT INTO settings (key, value, updated_at)
  VALUES (?, ?, ?)
  ON CONFLICT(key) DO UPDATE SET
    value = excluded.value,
    updated_at = excluded.updated_at
`, [key, value, Date.now()]);

3. Contact Operations

Get Contacts by Account

// Dexie
const contacts = await db.contacts
  .where('did')
  .equals(accountDid)
  .toArray();

// absurd-sql
const result = await db.exec(`
  SELECT * FROM contacts
  WHERE did = ?
  ORDER BY created_at DESC
`, [accountDid]);
const contacts = result[0]?.values || [];

Add Contact

// Dexie
await db.contacts.add({
  id: generateId(),
  did: accountDid,
  name,
  createdAt: Date.now(),
  updatedAt: Date.now()
});

// absurd-sql
await db.run(`
  INSERT INTO contacts (id, did, name, created_at, updated_at)
  VALUES (?, ?, ?, ?, ?)
`, [generateId(), accountDid, name, Date.now(), Date.now()]);

Transaction Mapping

Batch Operations

// Dexie
await db.transaction('rw', [db.accounts, db.contacts], async () => {
  await db.accounts.add(account);
  await db.contacts.bulkAdd(contacts);
});

// absurd-sql
await db.exec('BEGIN TRANSACTION;');
try {
  await db.run(`
    INSERT INTO accounts (did, public_key_hex, created_at, updated_at)
    VALUES (?, ?, ?, ?)
  `, [account.did, account.publicKeyHex, account.createdAt, account.updatedAt]);

  for (const contact of contacts) {
    await db.run(`
      INSERT INTO contacts (id, did, name, created_at, updated_at)
      VALUES (?, ?, ?, ?, ?)
    `, [contact.id, contact.did, contact.name, contact.createdAt, contact.updatedAt]);
  }
  await db.exec('COMMIT;');
} catch (error) {
  await db.exec('ROLLBACK;');
  throw error;
}

Migration Helper Functions

1. Data Export (Dexie to JSON)

async function exportDexieData(): Promise<MigrationData> {
  const db = new Dexie('TimeSafariDB');

  return {
    accounts: await db.accounts.toArray(),
    settings: await db.settings.toArray(),
    contacts: await db.contacts.toArray(),
    metadata: {
      version: '1.0.0',
      timestamp: Date.now(),
      dexieVersion: Dexie.version
    }
  };
}

2. Data Import (JSON to absurd-sql)

async function importToAbsurdSql(data: MigrationData): Promise<void> {
  await db.exec('BEGIN TRANSACTION;');
  try {
    // Import accounts
    for (const account of data.accounts) {
      await db.run(`
        INSERT INTO accounts (did, public_key_hex, created_at, updated_at)
        VALUES (?, ?, ?, ?)
      `, [account.did, account.publicKeyHex, account.createdAt, account.updatedAt]);
    }

    // Import settings
    for (const setting of data.settings) {
      await db.run(`
        INSERT INTO settings (key, value, updated_at)
        VALUES (?, ?, ?)
      `, [setting.key, setting.value, setting.updatedAt]);
    }

    // Import contacts
    for (const contact of data.contacts) {
      await db.run(`
        INSERT INTO contacts (id, did, name, created_at, updated_at)
        VALUES (?, ?, ?, ?, ?)
      `, [contact.id, contact.did, contact.name, contact.createdAt, contact.updatedAt]);
    }
    await db.exec('COMMIT;');
  } catch (error) {
    await db.exec('ROLLBACK;');
    throw error;
  }
}

3. Verification

async function verifyMigration(dexieData: MigrationData): Promise<boolean> {
  // Verify account count
  const accountResult = await db.exec('SELECT COUNT(*) as count FROM accounts');
  const accountCount = accountResult[0].values[0][0];
  if (accountCount !== dexieData.accounts.length) {
    return false;
  }

  // Verify settings count
  const settingsResult = await db.exec('SELECT COUNT(*) as count FROM settings');
  const settingsCount = settingsResult[0].values[0][0];
  if (settingsCount !== dexieData.settings.length) {
    return false;
  }

  // Verify contacts count
  const contactsResult = await db.exec('SELECT COUNT(*) as count FROM contacts');
  const contactsCount = contactsResult[0].values[0][0];
  if (contactsCount !== dexieData.contacts.length) {
    return false;
  }

  // Verify data integrity
  for (const account of dexieData.accounts) {
    const result = await db.exec(
      'SELECT * FROM accounts WHERE did = ?',
      [account.did]
    );
    const migratedAccount = result[0]?.values[0];
    if (!migratedAccount ||
        migratedAccount[1] !== account.publicKeyHex) { // public_key_hex is second column
      return false;
    }
  }

  return true;
}

Performance Considerations

1. Indexing

  • Dexie automatically creates indexes based on the schema
  • absurd-sql requires explicit index creation
  • Added indexes for frequently queried fields
  • Use PRAGMA journal_mode=MEMORY; for better performance

2. Batch Operations

  • Dexie has built-in bulk operations
  • absurd-sql uses transactions for batch operations
  • Consider chunking large datasets
  • Use prepared statements for repeated queries

3. Query Optimization

  • Dexie uses IndexedDB's native indexing
  • absurd-sql requires explicit query optimization
  • Use prepared statements for repeated queries
  • Consider using PRAGMA synchronous=NORMAL; for better performance

Error Handling

1. Common Errors

// Dexie errors
try {
  await db.accounts.add(account);
} catch (error) {
  if (error instanceof Dexie.ConstraintError) {
    // Handle duplicate key
  }
}

// absurd-sql errors
try {
  await db.run(`
    INSERT INTO accounts (did, public_key_hex, created_at, updated_at)
    VALUES (?, ?, ?, ?)
  `, [account.did, account.publicKeyHex, account.createdAt, account.updatedAt]);
} catch (error) {
  if (error.message.includes('UNIQUE constraint failed')) {
    // Handle duplicate key
  }
}

2. Transaction Recovery

// Dexie transaction
try {
  await db.transaction('rw', db.accounts, async () => {
    // Operations
  });
} catch (error) {
  // Dexie automatically rolls back
}

// absurd-sql transaction
try {
  await db.exec('BEGIN TRANSACTION;');
  // Operations
  await db.exec('COMMIT;');
} catch (error) {
  await db.exec('ROLLBACK;');
  throw error;
}

Migration Strategy

  1. Preparation

    • Export all Dexie data
    • Verify data integrity
    • Create SQLite schema
    • Setup indexes
  2. Migration

    • Import data in transactions
    • Verify each batch
    • Handle errors gracefully
    • Maintain backup
  3. Verification

    • Compare record counts
    • Verify data integrity
    • Test common queries
    • Validate relationships
  4. Cleanup

    • Remove Dexie database
    • Clear IndexedDB storage
    • Update application code
    • Remove old dependencies