Update SQL script with view changes for uptime tracking
- Replaced add_lastboottime_column.sql with comprehensive add_uptime_tracking.sql - Updates 3 views to include lastboottime and uptime_days columns: - vw_active_pcs: Active PCs with warranty info - vw_shopfloor_pcs: Shopfloor PCs - vw_recent_updates: Recently updated machines - Includes verification queries 🤖 Generated with [Claude Code](https://claude.com/claude-code) Co-Authored-By: Claude <noreply@anthropic.com>
This commit is contained in:
@@ -1,29 +0,0 @@
|
||||
-- Add lastboottime column to machines table for PC uptime tracking
|
||||
-- Run on production database
|
||||
-- Date: 2025-12-09
|
||||
|
||||
-- Check if column exists before adding
|
||||
SET @dbname = DATABASE();
|
||||
SET @tablename = 'machines';
|
||||
SET @columnname = 'lastboottime';
|
||||
SET @preparedStatement = (SELECT IF(
|
||||
(
|
||||
SELECT COUNT(*) FROM INFORMATION_SCHEMA.COLUMNS
|
||||
WHERE TABLE_SCHEMA = @dbname
|
||||
AND TABLE_NAME = @tablename
|
||||
AND COLUMN_NAME = @columnname
|
||||
) > 0,
|
||||
'SELECT ''Column lastboottime already exists'';',
|
||||
'ALTER TABLE machines ADD COLUMN lastboottime DATETIME NULL DEFAULT NULL AFTER lastupdated;'
|
||||
));
|
||||
|
||||
PREPARE alterIfNotExists FROM @preparedStatement;
|
||||
EXECUTE alterIfNotExists;
|
||||
DEALLOCATE PREPARE alterIfNotExists;
|
||||
|
||||
-- Verify the column was added
|
||||
SELECT COLUMN_NAME, DATA_TYPE, IS_NULLABLE, COLUMN_DEFAULT
|
||||
FROM INFORMATION_SCHEMA.COLUMNS
|
||||
WHERE TABLE_SCHEMA = DATABASE()
|
||||
AND TABLE_NAME = 'machines'
|
||||
AND COLUMN_NAME = 'lastboottime';
|
||||
133
sql/add_uptime_tracking.sql
Normal file
133
sql/add_uptime_tracking.sql
Normal file
@@ -0,0 +1,133 @@
|
||||
-- Add PC uptime tracking: lastboottime column and view updates
|
||||
-- Run on production database
|
||||
-- Date: 2025-12-09
|
||||
|
||||
-- ============================================================================
|
||||
-- STEP 1: Add lastboottime column to machines table (if not exists)
|
||||
-- ============================================================================
|
||||
SET @dbname = DATABASE();
|
||||
SET @tablename = 'machines';
|
||||
SET @columnname = 'lastboottime';
|
||||
SET @preparedStatement = (SELECT IF(
|
||||
(
|
||||
SELECT COUNT(*) FROM INFORMATION_SCHEMA.COLUMNS
|
||||
WHERE TABLE_SCHEMA = @dbname
|
||||
AND TABLE_NAME = @tablename
|
||||
AND COLUMN_NAME = @columnname
|
||||
) > 0,
|
||||
'SELECT ''Column lastboottime already exists'' AS status;',
|
||||
'ALTER TABLE machines ADD COLUMN lastboottime DATETIME NULL DEFAULT NULL AFTER lastupdated;'
|
||||
));
|
||||
|
||||
PREPARE alterIfNotExists FROM @preparedStatement;
|
||||
EXECUTE alterIfNotExists;
|
||||
DEALLOCATE PREPARE alterIfNotExists;
|
||||
|
||||
-- ============================================================================
|
||||
-- STEP 2: Update vw_active_pcs view to include lastboottime and uptime_days
|
||||
-- ============================================================================
|
||||
CREATE OR REPLACE VIEW vw_active_pcs AS
|
||||
SELECT
|
||||
pcmap.pcid,
|
||||
m.hostname,
|
||||
m.serialnumber,
|
||||
COALESCE(v.vendor, 'Unknown') AS manufacturer,
|
||||
md.modelnumber AS model,
|
||||
m.loggedinuser,
|
||||
m.machinenumber,
|
||||
COALESCE(os.operatingsystem, 'Unknown') AS operatingsystem,
|
||||
COALESCE(pt.typename, 'Unknown') AS pctype,
|
||||
COALESCE(pt.description, 'Unknown') AS typedescription,
|
||||
CASE
|
||||
WHEN w.enddate IS NULL THEN 'Unknown'
|
||||
WHEN w.enddate < CURDATE() THEN 'Expired'
|
||||
WHEN w.enddate < DATE_ADD(CURDATE(), INTERVAL 90 DAY) THEN 'Expiring Soon'
|
||||
ELSE 'Active'
|
||||
END AS warrantystatus,
|
||||
w.enddate AS warrantyenddate,
|
||||
CASE WHEN w.enddate IS NULL THEN NULL ELSE DATEDIFF(w.enddate, CURDATE()) END AS warrantydaysremaining,
|
||||
m.lastupdated,
|
||||
DATEDIFF(NOW(), m.lastupdated) AS daysold,
|
||||
m.lastboottime,
|
||||
DATEDIFF(NOW(), m.lastboottime) AS uptime_days
|
||||
FROM machines m
|
||||
JOIN pc_to_machine_id_mapping pcmap ON m.machineid = pcmap.new_machineid
|
||||
LEFT JOIN models md ON m.modelnumberid = md.modelnumberid
|
||||
LEFT JOIN vendors v ON md.vendorid = v.vendorid
|
||||
LEFT JOIN pctype pt ON m.pctypeid = pt.pctypeid
|
||||
LEFT JOIN operatingsystems os ON m.osid = os.osid
|
||||
LEFT JOIN warranties w ON m.machineid = w.machineid
|
||||
WHERE m.lastupdated > DATE_SUB(NOW(), INTERVAL 30 DAY)
|
||||
AND m.pctypeid IS NOT NULL;
|
||||
|
||||
-- ============================================================================
|
||||
-- STEP 3: Update vw_shopfloor_pcs view to include lastboottime and uptime_days
|
||||
-- ============================================================================
|
||||
CREATE OR REPLACE VIEW vw_shopfloor_pcs AS
|
||||
SELECT
|
||||
pcmap.pcid,
|
||||
m.hostname,
|
||||
m.serialnumber,
|
||||
v.vendor AS manufacturer,
|
||||
md.modelnumber AS model,
|
||||
m.loggedinuser,
|
||||
COALESCE(CONVERT(mo.machinenumber USING utf8mb4), CONVERT(m.machinenumber USING utf8mb4)) AS machinenumber,
|
||||
COALESCE(os.operatingsystem, 'Unknown') AS operatingsystem,
|
||||
m.lastupdated,
|
||||
m.lastboottime,
|
||||
DATEDIFF(NOW(), m.lastboottime) AS uptime_days
|
||||
FROM machines m
|
||||
JOIN pc_to_machine_id_mapping pcmap ON m.machineid = pcmap.new_machineid
|
||||
JOIN pctype pt ON m.pctypeid = pt.pctypeid
|
||||
LEFT JOIN machine_overrides mo ON pcmap.pcid = mo.pcid
|
||||
LEFT JOIN models md ON m.modelnumberid = md.modelnumberid
|
||||
LEFT JOIN vendors v ON md.vendorid = v.vendorid
|
||||
LEFT JOIN operatingsystems os ON m.osid = os.osid
|
||||
WHERE pt.typename = 'Shopfloor'
|
||||
AND m.lastupdated > DATE_SUB(NOW(), INTERVAL 30 DAY)
|
||||
AND m.pctypeid IS NOT NULL
|
||||
ORDER BY COALESCE(CONVERT(mo.machinenumber USING utf8mb4), CONVERT(m.machinenumber USING utf8mb4)), m.hostname;
|
||||
|
||||
-- ============================================================================
|
||||
-- STEP 4: Update vw_recent_updates view to include lastboottime and uptime_days
|
||||
-- ============================================================================
|
||||
CREATE OR REPLACE VIEW vw_recent_updates AS
|
||||
SELECT
|
||||
m.machineid,
|
||||
m.machinenumber,
|
||||
m.hostname,
|
||||
CASE
|
||||
WHEN m.pctypeid IS NOT NULL THEN CONCAT('PC - ', pt.typename)
|
||||
ELSE mt.machinetype
|
||||
END AS machine_type,
|
||||
v.vendor AS manufacturer,
|
||||
md.modelnumber AS model,
|
||||
m.lastupdated,
|
||||
DATEDIFF(NOW(), m.lastupdated) AS days_since_update,
|
||||
m.lastboottime,
|
||||
DATEDIFF(NOW(), m.lastboottime) AS uptime_days
|
||||
FROM machines m
|
||||
LEFT JOIN models md ON m.modelnumberid = md.modelnumberid
|
||||
LEFT JOIN vendors v ON md.vendorid = v.vendorid
|
||||
LEFT JOIN machinetypes mt ON m.machinetypeid = mt.machinetypeid
|
||||
LEFT JOIN pctype pt ON m.pctypeid = pt.pctypeid
|
||||
WHERE m.isactive = 1
|
||||
AND m.lastupdated > DATE_SUB(NOW(), INTERVAL 7 DAY)
|
||||
ORDER BY m.lastupdated DESC
|
||||
LIMIT 100;
|
||||
|
||||
-- ============================================================================
|
||||
-- STEP 5: Verify changes
|
||||
-- ============================================================================
|
||||
SELECT 'Column check:' AS verification;
|
||||
SELECT COLUMN_NAME, DATA_TYPE, IS_NULLABLE
|
||||
FROM INFORMATION_SCHEMA.COLUMNS
|
||||
WHERE TABLE_SCHEMA = DATABASE()
|
||||
AND TABLE_NAME = 'machines'
|
||||
AND COLUMN_NAME = 'lastboottime';
|
||||
|
||||
SELECT 'Views updated:' AS verification;
|
||||
SELECT TABLE_NAME, VIEW_DEFINITION LIKE '%lastboottime%' AS has_lastboottime
|
||||
FROM INFORMATION_SCHEMA.VIEWS
|
||||
WHERE TABLE_SCHEMA = DATABASE()
|
||||
AND TABLE_NAME IN ('vw_active_pcs', 'vw_shopfloor_pcs', 'vw_recent_updates');
|
||||
Reference in New Issue
Block a user