meteor_detection_system/meteor-web-backend/migrations/1766300000013_encrypt-private-keys.js
grabbit f557c06771 feat: complete database schema migration to UUID primary keys
## Database Migrations (18 new)
- Migrate all primary keys from SERIAL to UUID
- Add soft delete (deleted_at) to all 19 entities
- Add missing indexes for performance optimization
- Add CHECK constraints for data validation
- Add user audit fields (last_login_at, timezone, locale)
- Add weather station location fields (latitude, longitude, elevation)
- Add foreign key relationships (CameraDevice→Device, ValidatedEvent→WeatherStation)
- Prepare private key encryption fields

## Backend Entity Updates
- All entities updated with UUID primary keys
- Added @DeleteDateColumn for soft delete support
- Updated relations and foreign key types

## Backend Service/Controller Updates
- Changed ID parameters from number to string (UUID)
- Removed ParseIntPipe from controllers
- Updated TypeORM queries for string IDs

## Frontend Updates
- Updated all service interfaces to use string IDs
- Fixed CameraDevice.location as JSONB object
- Updated weather.ts with new fields (elevation, timezone)
- Added Supabase integration hooks and lib
- Fixed chart components for new data structure

## Cleanup
- Removed deprecated .claude/agents configuration files

🤖 Generated with [Claude Code](https://claude.com/claude-code)

Co-Authored-By: Claude Opus 4.5 <noreply@anthropic.com>
2025-12-21 03:33:26 +08:00

156 lines
4.8 KiB
JavaScript

/**
* Migration: Add encrypted storage for private keys
*
* Fixes: DeviceCertificate.privateKeyPem stored in plaintext - security risk
* Changes:
* - Add encrypted_private_key column for AES-256-GCM encrypted storage
* - Add encryption_key_id for key management
* - Add encryption_algorithm field
* - Mark private_key_pem as deprecated (not removed for backwards compatibility)
*
* Note: Actual encryption/decryption should be handled at application level.
* This migration only sets up the schema for encrypted storage.
*
* @type {import('node-pg-migrate').ColumnDefinitions | undefined}
*/
export const shorthands = undefined;
/**
* @param pgm {import('node-pg-migrate').MigrationBuilder}
* @param run {() => void | undefined}
* @returns {Promise<void> | void}
*/
export const up = (pgm) => {
console.log('Adding encrypted private key storage...');
// Add encryption-related columns
pgm.addColumns('device_certificates', {
encrypted_private_key: {
type: 'text',
notNull: false,
comment: 'AES-256-GCM encrypted private key (base64 encoded ciphertext + IV + auth tag)',
},
encryption_key_id: {
type: 'varchar(100)',
notNull: false,
comment: 'Identifier for the encryption key used (for key rotation support)',
},
encryption_algorithm: {
type: 'varchar(50)',
notNull: false,
default: 'AES-256-GCM',
comment: 'Encryption algorithm used',
},
encrypted_at: {
type: 'timestamptz',
notNull: false,
comment: 'Timestamp when the private key was encrypted',
},
});
// Add deprecation comment to old column
pgm.sql(`
COMMENT ON COLUMN device_certificates.private_key_pem IS
'DEPRECATED: Plaintext private key. Will be removed in future version.
Use encrypted_private_key instead for secure storage.
This column is kept for backwards compatibility during migration.';
`);
// Add index on encryption_key_id for key rotation queries
pgm.createIndex('device_certificates', 'encryption_key_id', {
name: 'idx_device_certificates_encryption_key_id',
where: 'encryption_key_id IS NOT NULL',
});
// Add CHECK constraint for encryption algorithm
pgm.addConstraint('device_certificates', 'chk_device_certificates_encryption_algorithm', {
check: "encryption_algorithm IS NULL OR encryption_algorithm IN ('AES-256-GCM', 'AES-256-CBC', 'ChaCha20-Poly1305')",
});
// Create a view that excludes private key data for safer queries
pgm.sql(`
CREATE OR REPLACE VIEW device_certificates_public AS
SELECT
id,
device_id,
serial_number,
fingerprint,
certificate_type,
status,
subject_dn,
issuer_dn,
certificate_pem,
public_key_pem,
key_algorithm,
key_size,
signature_algorithm,
issued_at,
expires_at,
revoked_at,
revocation_reason,
x509_extensions,
usage_count,
last_used_at,
renewal_notified_at,
created_at,
updated_at,
deleted_at,
-- Indicate if encrypted key exists without exposing it
CASE WHEN encrypted_private_key IS NOT NULL THEN true ELSE false END AS has_encrypted_key,
encryption_key_id,
encryption_algorithm,
encrypted_at
FROM device_certificates;
COMMENT ON VIEW device_certificates_public IS
'Safe view of device_certificates excluding private key data';
`);
console.log('Encrypted private key storage added.');
console.log('');
console.log('IMPORTANT: To complete the migration:');
console.log('1. Update application code to use encrypted_private_key');
console.log('2. Configure encryption key in environment');
console.log('3. Run data migration to encrypt existing private keys');
console.log('4. Once verified, clear private_key_pem column');
};
/**
* @param pgm {import('node-pg-migrate').MigrationBuilder}
* @param run {() => void | undefined}
* @returns {Promise<void> | void}
*/
export const down = (pgm) => {
console.log('Rolling back encrypted private key storage...');
// Drop view
pgm.sql('DROP VIEW IF EXISTS device_certificates_public;');
// Drop constraint
pgm.dropConstraint('device_certificates', 'chk_device_certificates_encryption_algorithm', {
ifExists: true,
});
// Drop index
pgm.dropIndex('device_certificates', 'encryption_key_id', {
name: 'idx_device_certificates_encryption_key_id',
ifExists: true,
});
// Drop columns
pgm.dropColumns('device_certificates', [
'encrypted_private_key',
'encryption_key_id',
'encryption_algorithm',
'encrypted_at',
]);
// Restore original comment
pgm.sql(`
COMMENT ON COLUMN device_certificates.private_key_pem IS
'Private key in PEM format (optional, for key recovery)';
`);
console.log('Encrypted private key storage rollback complete.');
};