Files
ScanLook/database/migration_current_global.sql
2026-01-22 00:36:01 -06:00

156 lines
4.4 KiB
SQL

-- Migration: Make CURRENT baseline global (not session-specific)
-- Run this ONCE to update existing database
BEGIN TRANSACTION;
-- Step 1: Create new global CURRENT table
CREATE TABLE IF NOT EXISTS BaselineInventory_Current_New (
current_id INTEGER PRIMARY KEY AUTOINCREMENT,
lot_number TEXT NOT NULL,
item TEXT NOT NULL,
description TEXT,
system_location TEXT,
system_bin TEXT NOT NULL,
system_quantity REAL NOT NULL,
upload_timestamp DATETIME DEFAULT CURRENT_TIMESTAMP,
UNIQUE(lot_number, system_bin)
);
-- Step 2: Copy latest CURRENT data (if any exists)
-- Get the most recent baseline_version
INSERT OR IGNORE INTO BaselineInventory_Current_New
(lot_number, item, description, system_location, system_bin, system_quantity, upload_timestamp)
SELECT
lot_number,
item,
description,
system_location,
system_bin,
system_quantity,
upload_timestamp
FROM BaselineInventory_Current
WHERE is_deleted = 0
AND baseline_version = (SELECT MAX(baseline_version) FROM BaselineInventory_Current WHERE is_deleted = 0)
ORDER BY upload_timestamp DESC;
-- Step 3: Drop old CURRENT table
DROP TABLE IF EXISTS BaselineInventory_Current;
-- Step 4: Rename new table
ALTER TABLE BaselineInventory_Current_New RENAME TO BaselineInventory_Current;
-- Step 5: Remove CURRENT columns from ScanEntries
-- SQLite doesn't support DROP COLUMN directly, so we recreate the table
CREATE TABLE ScanEntries_New (
entry_id INTEGER PRIMARY KEY AUTOINCREMENT,
session_id INTEGER NOT NULL,
location_count_id INTEGER NOT NULL,
lot_number TEXT NOT NULL,
item TEXT,
description TEXT,
scanned_location TEXT NOT NULL,
actual_weight REAL NOT NULL,
scanned_by INTEGER NOT NULL,
scan_timestamp DATETIME DEFAULT CURRENT_TIMESTAMP,
-- MASTER baseline reference (stored for performance)
master_status TEXT,
master_expected_location TEXT,
master_expected_weight REAL,
master_variance_lbs REAL,
master_variance_pct REAL,
-- Duplicate tracking
duplicate_status TEXT DEFAULT '00',
duplicate_info TEXT,
-- Metadata
comment TEXT,
is_deleted INTEGER DEFAULT 0,
deleted_by INTEGER,
deleted_timestamp DATETIME,
modified_timestamp DATETIME,
FOREIGN KEY (session_id) REFERENCES CountSessions(session_id),
FOREIGN KEY (location_count_id) REFERENCES LocationCounts(location_count_id),
FOREIGN KEY (scanned_by) REFERENCES Users(user_id),
FOREIGN KEY (deleted_by) REFERENCES Users(user_id)
);
-- Copy all scan data
INSERT INTO ScanEntries_New
SELECT
entry_id,
session_id,
location_count_id,
lot_number,
item,
description,
scanned_location,
actual_weight,
scanned_by,
scan_timestamp,
master_status,
master_expected_location,
master_expected_weight,
master_variance_lbs,
master_variance_pct,
duplicate_status,
duplicate_info,
comment,
is_deleted,
deleted_by,
deleted_timestamp,
modified_timestamp
FROM ScanEntries;
-- Drop old table and rename
DROP TABLE ScanEntries;
ALTER TABLE ScanEntries_New RENAME TO ScanEntries;
-- Recreate indexes
CREATE INDEX idx_scanentries_session ON ScanEntries(session_id);
CREATE INDEX idx_scanentries_location ON ScanEntries(location_count_id);
CREATE INDEX idx_scanentries_lot ON ScanEntries(lot_number);
CREATE INDEX idx_scanentries_deleted ON ScanEntries(is_deleted);
-- Step 6: Remove current_baseline_version from CountSessions
-- Recreate CountSessions table
CREATE TABLE CountSessions_New (
session_id INTEGER PRIMARY KEY AUTOINCREMENT,
session_name TEXT NOT NULL,
description TEXT,
status TEXT DEFAULT 'active',
branch TEXT DEFAULT 'Main',
created_by INTEGER NOT NULL,
created_timestamp DATETIME DEFAULT CURRENT_TIMESTAMP,
master_baseline_timestamp DATETIME,
current_baseline_timestamp DATETIME,
completed_timestamp DATETIME,
FOREIGN KEY (created_by) REFERENCES Users(user_id)
);
-- Copy session data
INSERT INTO CountSessions_New
SELECT
session_id,
session_name,
description,
status,
branch,
created_by,
created_timestamp,
master_baseline_timestamp,
current_baseline_timestamp,
completed_timestamp
FROM CountSessions;
-- Drop old and rename
DROP TABLE CountSessions;
ALTER TABLE CountSessions_New RENAME TO CountSessions;
COMMIT;
-- Migration complete!
-- CURRENT baseline is now global and always shows latest data