#!/usr/bin/env node /** * Initialize geofence tables in database.sqlite * This creates the schema for geofencing functionality */ const Database = require('better-sqlite3'); const path = require('path'); const fs = require('fs'); const dataDir = path.join(__dirname, '..', 'data'); const dbPath = path.join(dataDir, 'database.sqlite'); // Ensure data directory exists if (!fs.existsSync(dataDir)) { fs.mkdirSync(dataDir, { recursive: true }); console.log('✓ Created data directory'); } // Open existing database const db = new Database(dbPath); // Enable WAL mode for better concurrency db.pragma('journal_mode = WAL'); // Create Geofence table (simplified for MVP) db.exec(` CREATE TABLE IF NOT EXISTS Geofence ( id TEXT PRIMARY KEY, name TEXT NOT NULL, description TEXT, -- Geometry (circle only for MVP) shape_type TEXT NOT NULL DEFAULT 'circle', center_latitude REAL NOT NULL, center_longitude REAL NOT NULL, radius_meters INTEGER NOT NULL, -- Assignment (device_id is required for MVP) owner_id TEXT NOT NULL, device_id TEXT NOT NULL, -- Status & Metadata is_active INTEGER DEFAULT 1, color TEXT DEFAULT '#3b82f6', -- Timestamps created_at TEXT DEFAULT (datetime('now')), updated_at TEXT DEFAULT (datetime('now')), FOREIGN KEY (owner_id) REFERENCES User(id) ON DELETE CASCADE, FOREIGN KEY (device_id) REFERENCES Device(id) ON DELETE CASCADE, CHECK (shape_type = 'circle'), CHECK (radius_meters > 0 AND radius_meters <= 50000), CHECK (center_latitude BETWEEN -90 AND 90), CHECK (center_longitude BETWEEN -180 AND 180), CHECK (is_active IN (0, 1)) ); `); console.log('✓ Created Geofence table'); // Create GeofenceEvent table db.exec(` CREATE TABLE IF NOT EXISTS GeofenceEvent ( id INTEGER PRIMARY KEY AUTOINCREMENT, geofence_id TEXT NOT NULL, device_id TEXT NOT NULL, location_id INTEGER NOT NULL, -- Event details event_type TEXT NOT NULL, latitude REAL NOT NULL, longitude REAL NOT NULL, -- Metadata distance_from_center REAL, notification_sent INTEGER DEFAULT 0, notification_error TEXT, -- Timestamps timestamp TEXT NOT NULL, created_at TEXT DEFAULT (datetime('now')), FOREIGN KEY (geofence_id) REFERENCES Geofence(id) ON DELETE CASCADE, FOREIGN KEY (device_id) REFERENCES Device(id) ON DELETE CASCADE, CHECK (event_type IN ('enter', 'exit')), CHECK (notification_sent IN (0, 1, 2)) ); `); console.log('✓ Created GeofenceEvent table'); // Create GeofenceStatus table (for state tracking) db.exec(` CREATE TABLE IF NOT EXISTS GeofenceStatus ( id INTEGER PRIMARY KEY AUTOINCREMENT, device_id TEXT NOT NULL, geofence_id TEXT NOT NULL, -- Current status is_inside INTEGER NOT NULL DEFAULT 0, last_enter_time TEXT, last_exit_time TEXT, last_checked_at TEXT, -- Timestamps created_at TEXT DEFAULT (datetime('now')), updated_at TEXT DEFAULT (datetime('now')), FOREIGN KEY (device_id) REFERENCES Device(id) ON DELETE CASCADE, FOREIGN KEY (geofence_id) REFERENCES Geofence(id) ON DELETE CASCADE, UNIQUE(device_id, geofence_id), CHECK (is_inside IN (0, 1)) ); `); console.log('✓ Created GeofenceStatus table'); // Create indexes for performance db.exec(` CREATE INDEX IF NOT EXISTS idx_geofence_owner ON Geofence(owner_id); CREATE INDEX IF NOT EXISTS idx_geofence_device ON Geofence(device_id); CREATE INDEX IF NOT EXISTS idx_geofence_active ON Geofence(is_active); CREATE INDEX IF NOT EXISTS idx_geofence_event_geofence ON GeofenceEvent(geofence_id); CREATE INDEX IF NOT EXISTS idx_geofence_event_device ON GeofenceEvent(device_id); CREATE INDEX IF NOT EXISTS idx_geofence_event_timestamp ON GeofenceEvent(timestamp DESC); CREATE INDEX IF NOT EXISTS idx_geofence_event_notification ON GeofenceEvent(notification_sent); CREATE INDEX IF NOT EXISTS idx_geofence_event_composite ON GeofenceEvent(device_id, geofence_id, timestamp DESC); CREATE INDEX IF NOT EXISTS idx_geofence_status_device ON GeofenceStatus(device_id); CREATE INDEX IF NOT EXISTS idx_geofence_status_geofence ON GeofenceStatus(geofence_id); CREATE INDEX IF NOT EXISTS idx_geofence_status_inside ON GeofenceStatus(is_inside); `); console.log('✓ Created indexes'); // Get stats const geofenceCount = db.prepare('SELECT COUNT(*) as count FROM Geofence').get(); const eventCount = db.prepare('SELECT COUNT(*) as count FROM GeofenceEvent').get(); const statusCount = db.prepare('SELECT COUNT(*) as count FROM GeofenceStatus').get(); console.log(`\n✓ Geofence tables initialized successfully!`); console.log(` Path: ${dbPath}`); console.log(` Geofences: ${geofenceCount.count}`); console.log(` Events: ${eventCount.count}`); console.log(` Status records: ${statusCount.count}`); db.close();