## 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>
496 lines
11 KiB
JavaScript
496 lines
11 KiB
JavaScript
/**
|
|
* @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) => {
|
|
// Create device_registrations table
|
|
pgm.createTable('device_registrations', {
|
|
id: {
|
|
type: 'uuid',
|
|
primaryKey: true,
|
|
default: pgm.func('gen_random_uuid()'),
|
|
},
|
|
user_profile_id: {
|
|
type: 'uuid',
|
|
notNull: true,
|
|
references: 'user_profiles(id)',
|
|
onDelete: 'CASCADE',
|
|
},
|
|
claim_token: {
|
|
type: 'varchar(255)',
|
|
notNull: true,
|
|
unique: true,
|
|
},
|
|
claim_id: {
|
|
type: 'varchar(255)',
|
|
notNull: true,
|
|
unique: true,
|
|
},
|
|
fallback_pin: {
|
|
type: 'varchar(6)',
|
|
notNull: true,
|
|
},
|
|
registration_type: {
|
|
type: 'varchar(50)',
|
|
notNull: true,
|
|
default: 'qr_with_pin_fallback',
|
|
},
|
|
status: {
|
|
type: 'varchar(50)',
|
|
notNull: true,
|
|
default: 'pending',
|
|
},
|
|
device_type: {
|
|
type: 'varchar(100)',
|
|
},
|
|
device_name: {
|
|
type: 'varchar(255)',
|
|
},
|
|
hardware_fingerprint: {
|
|
type: 'jsonb',
|
|
},
|
|
device_info: {
|
|
type: 'jsonb',
|
|
},
|
|
location: {
|
|
type: 'jsonb',
|
|
},
|
|
user_agent: {
|
|
type: 'varchar(500)',
|
|
},
|
|
ip_address: {
|
|
type: 'inet',
|
|
},
|
|
challenge: {
|
|
type: 'varchar(255)',
|
|
},
|
|
challenge_response: {
|
|
type: 'varchar(255)',
|
|
},
|
|
device_id: {
|
|
type: 'uuid',
|
|
references: 'devices(id)',
|
|
onDelete: 'SET NULL',
|
|
},
|
|
qr_code_url: {
|
|
type: 'text',
|
|
},
|
|
websocket_url: {
|
|
type: 'varchar(255)',
|
|
},
|
|
error_message: {
|
|
type: 'text',
|
|
},
|
|
error_details: {
|
|
type: 'jsonb',
|
|
},
|
|
expires_at: {
|
|
type: 'timestamptz',
|
|
notNull: true,
|
|
},
|
|
claimed_at: {
|
|
type: 'timestamptz',
|
|
},
|
|
completed_at: {
|
|
type: 'timestamptz',
|
|
},
|
|
cancelled_at: {
|
|
type: 'timestamptz',
|
|
},
|
|
cancelled_by: {
|
|
type: 'uuid',
|
|
references: 'user_profiles(id)',
|
|
onDelete: 'SET NULL',
|
|
},
|
|
created_at: {
|
|
type: 'timestamptz',
|
|
notNull: true,
|
|
default: pgm.func('CURRENT_TIMESTAMP'),
|
|
},
|
|
updated_at: {
|
|
type: 'timestamptz',
|
|
notNull: true,
|
|
default: pgm.func('CURRENT_TIMESTAMP'),
|
|
},
|
|
});
|
|
|
|
// Create indexes
|
|
pgm.createIndex('device_registrations', 'claim_token');
|
|
pgm.createIndex('device_registrations', 'claim_id');
|
|
pgm.createIndex('device_registrations', ['user_profile_id', 'status']);
|
|
pgm.createIndex('device_registrations', 'expires_at');
|
|
pgm.createIndex('device_registrations', 'created_at');
|
|
|
|
// Create device_certificates table
|
|
pgm.createTable('device_certificates', {
|
|
id: {
|
|
type: 'uuid',
|
|
primaryKey: true,
|
|
default: pgm.func('gen_random_uuid()'),
|
|
},
|
|
device_id: {
|
|
type: 'uuid',
|
|
notNull: true,
|
|
references: 'devices(id)',
|
|
onDelete: 'CASCADE',
|
|
},
|
|
serial_number: {
|
|
type: 'varchar(100)',
|
|
notNull: true,
|
|
unique: true,
|
|
},
|
|
fingerprint: {
|
|
type: 'varchar(128)',
|
|
notNull: true,
|
|
unique: true,
|
|
},
|
|
certificate_type: {
|
|
type: 'varchar(50)',
|
|
notNull: true,
|
|
default: 'device',
|
|
},
|
|
status: {
|
|
type: 'varchar(50)',
|
|
notNull: true,
|
|
default: 'active',
|
|
},
|
|
subject_dn: {
|
|
type: 'text',
|
|
notNull: true,
|
|
},
|
|
issuer_dn: {
|
|
type: 'text',
|
|
notNull: true,
|
|
},
|
|
certificate_pem: {
|
|
type: 'text',
|
|
notNull: true,
|
|
},
|
|
private_key_pem: {
|
|
type: 'text',
|
|
},
|
|
public_key_pem: {
|
|
type: 'text',
|
|
notNull: true,
|
|
},
|
|
key_algorithm: {
|
|
type: 'varchar(50)',
|
|
notNull: true,
|
|
},
|
|
key_size: {
|
|
type: 'integer',
|
|
notNull: true,
|
|
},
|
|
signature_algorithm: {
|
|
type: 'varchar(50)',
|
|
notNull: true,
|
|
},
|
|
issued_at: {
|
|
type: 'timestamptz',
|
|
notNull: true,
|
|
},
|
|
expires_at: {
|
|
type: 'timestamptz',
|
|
notNull: true,
|
|
},
|
|
revoked_at: {
|
|
type: 'timestamptz',
|
|
},
|
|
revocation_reason: {
|
|
type: 'varchar(100)',
|
|
},
|
|
x509_extensions: {
|
|
type: 'jsonb',
|
|
},
|
|
usage_count: {
|
|
type: 'bigint',
|
|
notNull: true,
|
|
default: 0,
|
|
},
|
|
last_used_at: {
|
|
type: 'timestamptz',
|
|
},
|
|
renewal_notified_at: {
|
|
type: 'timestamptz',
|
|
},
|
|
created_at: {
|
|
type: 'timestamptz',
|
|
notNull: true,
|
|
default: pgm.func('CURRENT_TIMESTAMP'),
|
|
},
|
|
updated_at: {
|
|
type: 'timestamptz',
|
|
notNull: true,
|
|
default: pgm.func('CURRENT_TIMESTAMP'),
|
|
},
|
|
});
|
|
|
|
// Create indexes for device_certificates
|
|
pgm.createIndex('device_certificates', 'device_id');
|
|
pgm.createIndex('device_certificates', 'status');
|
|
pgm.createIndex('device_certificates', 'expires_at');
|
|
pgm.createIndex('device_certificates', 'serial_number', { unique: true });
|
|
pgm.createIndex('device_certificates', 'fingerprint', { unique: true });
|
|
|
|
// Create device_configurations table
|
|
pgm.createTable('device_configurations', {
|
|
id: {
|
|
type: 'uuid',
|
|
primaryKey: true,
|
|
default: pgm.func('gen_random_uuid()'),
|
|
},
|
|
device_id: {
|
|
type: 'uuid',
|
|
notNull: true,
|
|
references: 'devices(id)',
|
|
onDelete: 'CASCADE',
|
|
},
|
|
version: {
|
|
type: 'varchar(50)',
|
|
notNull: true,
|
|
},
|
|
status: {
|
|
type: 'varchar(50)',
|
|
notNull: true,
|
|
default: 'pending',
|
|
},
|
|
source: {
|
|
type: 'varchar(50)',
|
|
notNull: true,
|
|
default: 'default',
|
|
},
|
|
is_active: {
|
|
type: 'boolean',
|
|
notNull: true,
|
|
default: false,
|
|
},
|
|
device_settings: {
|
|
type: 'jsonb',
|
|
notNull: true,
|
|
},
|
|
network_settings: {
|
|
type: 'jsonb',
|
|
notNull: true,
|
|
},
|
|
camera_settings: {
|
|
type: 'jsonb',
|
|
notNull: true,
|
|
},
|
|
detection_settings: {
|
|
type: 'jsonb',
|
|
notNull: true,
|
|
},
|
|
storage_settings: {
|
|
type: 'jsonb',
|
|
notNull: true,
|
|
},
|
|
monitoring_settings: {
|
|
type: 'jsonb',
|
|
notNull: true,
|
|
},
|
|
security_settings: {
|
|
type: 'jsonb',
|
|
notNull: true,
|
|
},
|
|
configuration_signature: {
|
|
type: 'varchar(255)',
|
|
notNull: true,
|
|
},
|
|
checksum: {
|
|
type: 'varchar(64)',
|
|
notNull: true,
|
|
},
|
|
applied_at: {
|
|
type: 'timestamptz',
|
|
},
|
|
applied_by_device: {
|
|
type: 'boolean',
|
|
notNull: true,
|
|
default: false,
|
|
},
|
|
rollback_configuration_id: {
|
|
type: 'uuid',
|
|
},
|
|
validation_result: {
|
|
type: 'jsonb',
|
|
},
|
|
deployment_metadata: {
|
|
type: 'jsonb',
|
|
},
|
|
created_at: {
|
|
type: 'timestamptz',
|
|
notNull: true,
|
|
default: pgm.func('CURRENT_TIMESTAMP'),
|
|
},
|
|
updated_at: {
|
|
type: 'timestamptz',
|
|
notNull: true,
|
|
default: pgm.func('CURRENT_TIMESTAMP'),
|
|
},
|
|
});
|
|
|
|
// Create indexes for device_configurations
|
|
pgm.createIndex('device_configurations', 'device_id');
|
|
pgm.createIndex('device_configurations', 'status');
|
|
pgm.createIndex('device_configurations', 'version');
|
|
pgm.createIndex('device_configurations', 'created_at');
|
|
pgm.createIndex('device_configurations', 'is_active');
|
|
|
|
// Create device_security_events table
|
|
pgm.createTable('device_security_events', {
|
|
id: {
|
|
type: 'uuid',
|
|
primaryKey: true,
|
|
default: pgm.func('gen_random_uuid()'),
|
|
},
|
|
device_id: {
|
|
type: 'uuid',
|
|
references: 'devices(id)',
|
|
onDelete: 'SET NULL',
|
|
},
|
|
event_type: {
|
|
type: 'varchar(50)',
|
|
notNull: true,
|
|
},
|
|
severity: {
|
|
type: 'varchar(20)',
|
|
notNull: true,
|
|
},
|
|
status: {
|
|
type: 'varchar(50)',
|
|
notNull: true,
|
|
default: 'open',
|
|
},
|
|
title: {
|
|
type: 'varchar(255)',
|
|
notNull: true,
|
|
},
|
|
description: {
|
|
type: 'text',
|
|
notNull: true,
|
|
},
|
|
source_ip: {
|
|
type: 'inet',
|
|
},
|
|
user_agent: {
|
|
type: 'varchar(500)',
|
|
},
|
|
request_path: {
|
|
type: 'varchar(500)',
|
|
},
|
|
request_method: {
|
|
type: 'varchar(10)',
|
|
},
|
|
hardware_fingerprint: {
|
|
type: 'varchar(255)',
|
|
},
|
|
certificate_serial: {
|
|
type: 'varchar(100)',
|
|
},
|
|
event_data: {
|
|
type: 'jsonb',
|
|
},
|
|
detection_rules: {
|
|
type: 'jsonb',
|
|
},
|
|
risk_score: {
|
|
type: 'integer',
|
|
notNull: true,
|
|
default: 0,
|
|
},
|
|
false_positive_probability: {
|
|
type: 'float',
|
|
notNull: true,
|
|
default: 0.0,
|
|
},
|
|
resolved: {
|
|
type: 'boolean',
|
|
notNull: true,
|
|
default: false,
|
|
},
|
|
resolved_at: {
|
|
type: 'timestamptz',
|
|
},
|
|
resolved_by: {
|
|
type: 'varchar(255)',
|
|
},
|
|
resolution_notes: {
|
|
type: 'text',
|
|
},
|
|
automated_response: {
|
|
type: 'jsonb',
|
|
},
|
|
related_events: {
|
|
type: 'uuid[]',
|
|
default: pgm.func("'{}'::uuid[]"),
|
|
},
|
|
tags: {
|
|
type: 'varchar[]',
|
|
default: pgm.func("'{}'::varchar[]"),
|
|
},
|
|
created_at: {
|
|
type: 'timestamptz',
|
|
notNull: true,
|
|
default: pgm.func('CURRENT_TIMESTAMP'),
|
|
},
|
|
});
|
|
|
|
// Create indexes for device_security_events
|
|
pgm.createIndex('device_security_events', 'device_id');
|
|
pgm.createIndex('device_security_events', 'event_type');
|
|
pgm.createIndex('device_security_events', 'severity');
|
|
pgm.createIndex('device_security_events', 'status');
|
|
pgm.createIndex('device_security_events', 'created_at');
|
|
pgm.createIndex('device_security_events', 'source_ip');
|
|
pgm.createIndex('device_security_events', 'resolved');
|
|
|
|
// Add updated_at trigger for all tables
|
|
pgm.sql(`
|
|
CREATE OR REPLACE FUNCTION update_updated_at_column()
|
|
RETURNS TRIGGER AS $$
|
|
BEGIN
|
|
NEW.updated_at = CURRENT_TIMESTAMP;
|
|
RETURN NEW;
|
|
END;
|
|
$$ language 'plpgsql';
|
|
`);
|
|
|
|
pgm.sql(`
|
|
CREATE TRIGGER update_device_registrations_updated_at BEFORE UPDATE
|
|
ON device_registrations FOR EACH ROW EXECUTE FUNCTION update_updated_at_column();
|
|
`);
|
|
|
|
pgm.sql(`
|
|
CREATE TRIGGER update_device_certificates_updated_at BEFORE UPDATE
|
|
ON device_certificates FOR EACH ROW EXECUTE FUNCTION update_updated_at_column();
|
|
`);
|
|
|
|
pgm.sql(`
|
|
CREATE TRIGGER update_device_configurations_updated_at BEFORE UPDATE
|
|
ON device_configurations FOR EACH ROW EXECUTE FUNCTION update_updated_at_column();
|
|
`);
|
|
};
|
|
|
|
/**
|
|
* @param pgm {import('node-pg-migrate').MigrationBuilder}
|
|
* @param run {() => void | undefined}
|
|
* @returns {Promise<void> | void}
|
|
*/
|
|
export const down = (pgm) => {
|
|
// Drop triggers
|
|
pgm.sql('DROP TRIGGER IF EXISTS update_device_registrations_updated_at ON device_registrations');
|
|
pgm.sql('DROP TRIGGER IF EXISTS update_device_certificates_updated_at ON device_certificates');
|
|
pgm.sql('DROP TRIGGER IF EXISTS update_device_configurations_updated_at ON device_configurations');
|
|
|
|
// Drop tables
|
|
pgm.dropTable('device_security_events');
|
|
pgm.dropTable('device_configurations');
|
|
pgm.dropTable('device_certificates');
|
|
pgm.dropTable('device_registrations');
|
|
}; |