MVP
This commit is contained in:
145
phase1_database_migration.sql
Normal file
145
phase1_database_migration.sql
Normal file
@@ -0,0 +1,145 @@
|
||||
-- ============================================================================
|
||||
-- PHASE 1: Database Migration for Time Tracking & Alerts
|
||||
-- Database: machine_data
|
||||
-- Version: 1.0
|
||||
-- ============================================================================
|
||||
|
||||
-- ----------------------------------------------------------------------------
|
||||
-- Table 1: KPI Snapshots (Time-series data for graphs)
|
||||
-- ----------------------------------------------------------------------------
|
||||
CREATE TABLE IF NOT EXISTS kpi_snapshots (
|
||||
id INT AUTO_INCREMENT PRIMARY KEY,
|
||||
timestamp BIGINT NOT NULL COMMENT 'Unix timestamp in milliseconds',
|
||||
work_order_id VARCHAR(255),
|
||||
oee_percent DECIMAL(5,2) DEFAULT 0,
|
||||
availability_percent DECIMAL(5,2) DEFAULT 0,
|
||||
performance_percent DECIMAL(5,2) DEFAULT 0,
|
||||
quality_percent DECIMAL(5,2) DEFAULT 0,
|
||||
cycle_count INT DEFAULT 0,
|
||||
good_parts INT DEFAULT 0,
|
||||
scrap_count INT DEFAULT 0,
|
||||
operating_time DECIMAL(10,2) DEFAULT 0 COMMENT 'Accumulated seconds in state 1',
|
||||
downtime DECIMAL(10,2) DEFAULT 0 COMMENT 'Accumulated seconds in state 0 while tracking',
|
||||
machine_state INT DEFAULT 0 COMMENT 'Current machine state: 0 or 1',
|
||||
created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
|
||||
|
||||
INDEX idx_timestamp (timestamp),
|
||||
INDEX idx_work_order (work_order_id),
|
||||
INDEX idx_created_at (created_at)
|
||||
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COMMENT='KPI data snapshots for trending and graphs';
|
||||
|
||||
-- ----------------------------------------------------------------------------
|
||||
-- Table 2: Alert History (Manual + Automatic alerts)
|
||||
-- ----------------------------------------------------------------------------
|
||||
CREATE TABLE IF NOT EXISTS alert_history (
|
||||
id INT AUTO_INCREMENT PRIMARY KEY,
|
||||
timestamp BIGINT NOT NULL COMMENT 'Unix timestamp in milliseconds',
|
||||
alert_type VARCHAR(100) NOT NULL,
|
||||
description TEXT,
|
||||
severity VARCHAR(20) NOT NULL COMMENT 'info, warning, critical',
|
||||
source VARCHAR(50) NOT NULL COMMENT 'manual or automatic',
|
||||
work_order_id VARCHAR(255),
|
||||
acknowledged BOOLEAN DEFAULT 0,
|
||||
acknowledged_at BIGINT,
|
||||
acknowledged_by VARCHAR(100),
|
||||
auto_resolved BOOLEAN DEFAULT 0,
|
||||
resolved_at BIGINT,
|
||||
created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
|
||||
|
||||
INDEX idx_timestamp (timestamp),
|
||||
INDEX idx_severity (severity),
|
||||
INDEX idx_acknowledged (acknowledged),
|
||||
INDEX idx_work_order (work_order_id),
|
||||
INDEX idx_source (source)
|
||||
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COMMENT='Alert history for both manual and automatic alerts';
|
||||
|
||||
-- ----------------------------------------------------------------------------
|
||||
-- Table 3: Shift Definitions (Reference data)
|
||||
-- ----------------------------------------------------------------------------
|
||||
CREATE TABLE IF NOT EXISTS shift_definitions (
|
||||
id INT AUTO_INCREMENT PRIMARY KEY,
|
||||
shift_name VARCHAR(50) NOT NULL,
|
||||
start_hour INT NOT NULL COMMENT '0-23',
|
||||
start_minute INT NOT NULL DEFAULT 0,
|
||||
end_hour INT NOT NULL COMMENT '0-23',
|
||||
end_minute INT NOT NULL DEFAULT 0,
|
||||
created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
|
||||
|
||||
UNIQUE KEY unique_shift_name (shift_name)
|
||||
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COMMENT='Shift definitions for time range filtering';
|
||||
|
||||
-- Seed shift data
|
||||
INSERT IGNORE INTO shift_definitions (id, shift_name, start_hour, start_minute, end_hour, end_minute) VALUES
|
||||
(1, 'Day Shift', 6, 0, 15, 0),
|
||||
(2, 'Evening Shift', 15, 0, 23, 0),
|
||||
(3, 'Night Shift', 23, 0, 6, 0);
|
||||
|
||||
-- ----------------------------------------------------------------------------
|
||||
-- Table 4: Session State (For crash recovery - Option 2)
|
||||
-- ----------------------------------------------------------------------------
|
||||
CREATE TABLE IF NOT EXISTS session_state (
|
||||
id INT AUTO_INCREMENT PRIMARY KEY,
|
||||
session_key VARCHAR(50) NOT NULL COMMENT 'Always "current_session" - single row table',
|
||||
work_order_id VARCHAR(255),
|
||||
cycle_count INT DEFAULT 0,
|
||||
production_start_time BIGINT COMMENT 'Unix timestamp when tracking started',
|
||||
operating_time DECIMAL(10,2) DEFAULT 0,
|
||||
downtime DECIMAL(10,2) DEFAULT 0,
|
||||
last_update_time BIGINT,
|
||||
tracking_enabled BOOLEAN DEFAULT 0,
|
||||
machine_state INT DEFAULT 0,
|
||||
scrap_prompt_issued_for VARCHAR(255),
|
||||
updated_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP,
|
||||
|
||||
UNIQUE KEY unique_session (session_key)
|
||||
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COMMENT='Current session state for crash recovery';
|
||||
|
||||
-- Initialize the single session row
|
||||
INSERT IGNORE INTO session_state (session_key, work_order_id, cycle_count, tracking_enabled)
|
||||
VALUES ('current_session', NULL, 0, 0);
|
||||
|
||||
-- ----------------------------------------------------------------------------
|
||||
-- Table 5: Add columns to existing work_orders table (if not present)
|
||||
-- ----------------------------------------------------------------------------
|
||||
-- Check if scrap_count column exists, add if missing
|
||||
SET @col_exists = 0;
|
||||
SELECT COUNT(*) INTO @col_exists
|
||||
FROM INFORMATION_SCHEMA.COLUMNS
|
||||
WHERE TABLE_SCHEMA = 'machine_data'
|
||||
AND TABLE_NAME = 'work_orders'
|
||||
AND COLUMN_NAME = 'scrap_count';
|
||||
|
||||
SET @query = IF(@col_exists = 0,
|
||||
'ALTER TABLE work_orders ADD COLUMN scrap_count INT DEFAULT 0 AFTER good_parts',
|
||||
'SELECT "Column scrap_count already exists" AS Info');
|
||||
PREPARE stmt FROM @query;
|
||||
EXECUTE stmt;
|
||||
DEALLOCATE PREPARE stmt;
|
||||
|
||||
-- Check if scrap_parts column exists (legacy), rename to scrap_count if needed
|
||||
SET @col_exists_legacy = 0;
|
||||
SELECT COUNT(*) INTO @col_exists_legacy
|
||||
FROM INFORMATION_SCHEMA.COLUMNS
|
||||
WHERE TABLE_SCHEMA = 'machine_data'
|
||||
AND TABLE_NAME = 'work_orders'
|
||||
AND COLUMN_NAME = 'scrap_parts';
|
||||
|
||||
SET @query = IF(@col_exists_legacy > 0,
|
||||
'ALTER TABLE work_orders CHANGE scrap_parts scrap_count INT DEFAULT 0',
|
||||
'SELECT "No legacy scrap_parts column to rename" AS Info');
|
||||
PREPARE stmt FROM @query;
|
||||
EXECUTE stmt;
|
||||
DEALLOCATE PREPARE stmt;
|
||||
|
||||
-- ----------------------------------------------------------------------------
|
||||
-- Verification Queries (Run these to confirm migration success)
|
||||
-- ----------------------------------------------------------------------------
|
||||
-- SELECT COUNT(*) AS kpi_snapshots_count FROM kpi_snapshots;
|
||||
-- SELECT COUNT(*) AS alert_history_count FROM alert_history;
|
||||
-- SELECT * FROM shift_definitions;
|
||||
-- SELECT * FROM session_state WHERE session_key = 'current_session';
|
||||
-- SHOW COLUMNS FROM work_orders;
|
||||
|
||||
-- ============================================================================
|
||||
-- END OF MIGRATION
|
||||
-- ============================================================================
|
||||
Reference in New Issue
Block a user