Remove legacy pc tables, fix ASP issues, update dashboard APIs
Database changes (run sql/migration_drop_pc_tables.sql on prod): - Drop pc, pc_backup_phase2, pc_to_machine_id_mapping tables - Rename pcid columns to machineid in machineoverrides, dualpathassignments, networkinterfaces - Recreate 9 views to use machines.machineid instead of pcid - Clean orphaned records and add FK constraints to machines table ASP fixes: - editprinter.asp: Fix CLng type mismatch when no printerid provided - includes/sql.asp: Remove AutoDeactivateExpiredNotifications (endtime handles expiry) - includes/leftsidebar.asp: Update fiscal week banner styling, remove dead Information link - charts/warrantychart.asp: Use vw_warranty_status instead of pc table Dashboard API renames (naming convention): - shopfloor-dashboard: Update to use apishopfloor.asp, apibusinessunits.asp - tv-dashboard: Rename api_slides.asp to apislides.asp 🤖 Generated with [Claude Code](https://claude.com/claude-code) Co-Authored-By: Claude Opus 4.5 <noreply@anthropic.com>
This commit is contained in:
23
sql/drop_legacy_pc_tables.sql
Normal file
23
sql/drop_legacy_pc_tables.sql
Normal file
@@ -0,0 +1,23 @@
|
||||
-- ============================================================================
|
||||
-- Drop Legacy PC Tables
|
||||
--
|
||||
-- These tables are no longer used after PC migration to machines table.
|
||||
-- All ASP code now uses machines table or vw_warranty_status view.
|
||||
--
|
||||
-- Run this AFTER verifying the application works correctly.
|
||||
-- ============================================================================
|
||||
|
||||
-- Verify no dependencies before dropping
|
||||
-- SELECT * FROM information_schema.KEY_COLUMN_USAGE
|
||||
-- WHERE REFERENCED_TABLE_NAME IN ('pc', 'pc_backup_phase2');
|
||||
|
||||
-- Drop the legacy tables
|
||||
DROP TABLE IF EXISTS pc_backup_phase2;
|
||||
DROP TABLE IF EXISTS pc;
|
||||
|
||||
-- Verify tables are gone
|
||||
SHOW TABLES LIKE 'pc%';
|
||||
|
||||
-- Expected remaining tables:
|
||||
-- pc_to_machine_id_mapping (still needed by views)
|
||||
-- pctype (still needed for PC type lookups)
|
||||
287
sql/migration_drop_pc_tables.sql
Normal file
287
sql/migration_drop_pc_tables.sql
Normal file
@@ -0,0 +1,287 @@
|
||||
-- ============================================================================
|
||||
-- Migration: Drop Legacy PC Tables
|
||||
--
|
||||
-- This script removes the old pc table and pc_to_machine_id_mapping after
|
||||
-- migrating all dependencies to use machines.machineid directly.
|
||||
--
|
||||
-- IMPORTANT: Run this on DEV first and test thoroughly before production!
|
||||
-- ============================================================================
|
||||
|
||||
-- ============================================================================
|
||||
-- STEP 1: Drop Foreign Key Constraints referencing pc table
|
||||
-- ============================================================================
|
||||
|
||||
ALTER TABLE commconfig DROP FOREIGN KEY commconfig_ibfk_1;
|
||||
ALTER TABLE dncconfig DROP FOREIGN KEY dncconfig_ibfk_1;
|
||||
ALTER TABLE dualpathassignments DROP FOREIGN KEY dualpathassignments_ibfk_1;
|
||||
ALTER TABLE machineoverrides DROP FOREIGN KEY machineoverrides_ibfk_1;
|
||||
ALTER TABLE networkinterfaces DROP FOREIGN KEY networkinterfaces_ibfk_1;
|
||||
|
||||
-- ============================================================================
|
||||
-- STEP 2: Drop Views that depend on pc_to_machine_id_mapping
|
||||
-- ============================================================================
|
||||
|
||||
DROP VIEW IF EXISTS vw_active_pcs;
|
||||
DROP VIEW IF EXISTS vw_dnc_config;
|
||||
DROP VIEW IF EXISTS vw_engineer_pcs;
|
||||
DROP VIEW IF EXISTS vw_pc_network_summary;
|
||||
DROP VIEW IF EXISTS vw_pc_resolved_machines;
|
||||
DROP VIEW IF EXISTS vw_pcs_by_hardware;
|
||||
DROP VIEW IF EXISTS vw_shopfloor_comm_config;
|
||||
DROP VIEW IF EXISTS vw_shopfloor_pcs;
|
||||
DROP VIEW IF EXISTS vw_standard_pcs;
|
||||
|
||||
-- ============================================================================
|
||||
-- STEP 3: Update tables - rename pcid columns to machineid
|
||||
-- ============================================================================
|
||||
|
||||
ALTER TABLE machineoverrides CHANGE COLUMN pcid machineid INT(11);
|
||||
ALTER TABLE dualpathassignments CHANGE COLUMN pcid machineid INT(11);
|
||||
ALTER TABLE networkinterfaces CHANGE COLUMN pcid machineid INT(11);
|
||||
|
||||
-- ============================================================================
|
||||
-- STEP 4: Clean up orphaned records (referencing non-existent machineids)
|
||||
-- ============================================================================
|
||||
|
||||
DELETE FROM dualpathassignments WHERE machineid NOT IN (SELECT machineid FROM machines);
|
||||
DELETE FROM networkinterfaces WHERE machineid NOT IN (SELECT machineid FROM machines);
|
||||
DELETE FROM commconfig WHERE machineid NOT IN (SELECT machineid FROM machines);
|
||||
DELETE FROM dncconfig WHERE machineid NOT IN (SELECT machineid FROM machines);
|
||||
DELETE FROM machineoverrides WHERE machineid NOT IN (SELECT machineid FROM machines);
|
||||
|
||||
-- ============================================================================
|
||||
-- STEP 5: Add new FK constraints pointing to machines table
|
||||
-- ============================================================================
|
||||
|
||||
ALTER TABLE machineoverrides ADD CONSTRAINT fk_machineoverrides_machines
|
||||
FOREIGN KEY (machineid) REFERENCES machines(machineid);
|
||||
ALTER TABLE dualpathassignments ADD CONSTRAINT fk_dualpathassignments_machines
|
||||
FOREIGN KEY (machineid) REFERENCES machines(machineid);
|
||||
ALTER TABLE networkinterfaces ADD CONSTRAINT fk_networkinterfaces_machines
|
||||
FOREIGN KEY (machineid) REFERENCES machines(machineid);
|
||||
ALTER TABLE commconfig ADD CONSTRAINT fk_commconfig_machines
|
||||
FOREIGN KEY (machineid) REFERENCES machines(machineid);
|
||||
ALTER TABLE dncconfig ADD CONSTRAINT fk_dncconfig_machines
|
||||
FOREIGN KEY (machineid) REFERENCES machines(machineid);
|
||||
|
||||
-- ============================================================================
|
||||
-- STEP 6: Drop the legacy tables
|
||||
-- ============================================================================
|
||||
|
||||
DROP TABLE IF EXISTS pc_backup_phase2;
|
||||
DROP TABLE IF EXISTS pc;
|
||||
DROP TABLE IF EXISTS pc_to_machine_id_mapping;
|
||||
|
||||
-- ============================================================================
|
||||
-- STEP 7: Recreate Views using machines.machineid instead of pcid
|
||||
-- ============================================================================
|
||||
|
||||
-- vw_active_pcs: All active PCs (updated in last 30 days)
|
||||
CREATE VIEW vw_active_pcs AS
|
||||
SELECT
|
||||
m.machineid,
|
||||
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
|
||||
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;
|
||||
|
||||
-- vw_dnc_config: PCs with DNC/communication config
|
||||
CREATE VIEW vw_dnc_config AS
|
||||
SELECT
|
||||
m.machineid,
|
||||
m.hostname,
|
||||
m.machinenumber,
|
||||
c.address AS ip_address,
|
||||
c.port AS socket,
|
||||
c.settings AS config_settings,
|
||||
ct.typename AS comm_type
|
||||
FROM machines m
|
||||
LEFT JOIN communications c ON m.machineid = c.machineid AND c.isactive = 1
|
||||
LEFT JOIN comstypes ct ON c.comstypeid = ct.comstypeid
|
||||
WHERE m.pctypeid IS NOT NULL
|
||||
AND ct.typename IN ('IP', 'Serial')
|
||||
ORDER BY m.hostname, ct.typename;
|
||||
|
||||
-- vw_engineer_pcs: Engineer-type PCs
|
||||
CREATE VIEW vw_engineer_pcs AS
|
||||
SELECT
|
||||
m.machineid,
|
||||
m.hostname,
|
||||
m.serialnumber,
|
||||
v.vendor AS manufacturer,
|
||||
md.modelnumber AS model,
|
||||
m.loggedinuser,
|
||||
m.machinenumber,
|
||||
COALESCE(os.operatingsystem, 'Unknown') AS operatingsystem,
|
||||
m.lastupdated
|
||||
FROM machines m
|
||||
JOIN pctype pt ON m.pctypeid = pt.pctypeid
|
||||
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 = 'Engineer'
|
||||
AND m.lastupdated > DATE_SUB(NOW(), INTERVAL 30 DAY)
|
||||
AND m.pctypeid IS NOT NULL
|
||||
ORDER BY m.hostname;
|
||||
|
||||
-- vw_pc_network_summary: Network interface summary per PC
|
||||
CREATE VIEW vw_pc_network_summary AS
|
||||
SELECT
|
||||
m.machineid,
|
||||
m.hostname,
|
||||
m.machinenumber,
|
||||
COUNT(c.comid) AS interface_count,
|
||||
GROUP_CONCAT(c.address ORDER BY c.comid SEPARATOR ', ') AS ip_addresses,
|
||||
GROUP_CONCAT(c.macaddress ORDER BY c.comid SEPARATOR ', ') AS mac_addresses
|
||||
FROM machines m
|
||||
LEFT JOIN communications c ON m.machineid = c.machineid
|
||||
AND c.comstypeid = (SELECT comstypeid FROM comstypes WHERE typename = 'Network_Interface' LIMIT 1)
|
||||
AND c.isactive = 1
|
||||
WHERE m.pctypeid IS NOT NULL
|
||||
GROUP BY m.machineid, m.hostname, m.machinenumber
|
||||
ORDER BY m.hostname;
|
||||
|
||||
-- vw_pc_resolved_machines: PCs with their assigned/controlled machines
|
||||
CREATE VIEW vw_pc_resolved_machines AS
|
||||
SELECT
|
||||
m1.machineid AS pc_machineid,
|
||||
m1.hostname AS pc_hostname,
|
||||
m1.machinenumber AS pc_machinenumber,
|
||||
m2.machineid AS assigned_machine_id,
|
||||
m2.machinenumber AS assigned_machine_number,
|
||||
m2.hostname AS assigned_machine_hostname,
|
||||
rt.relationshiptype
|
||||
FROM machines m1
|
||||
LEFT JOIN machinerelationships mr ON m1.machineid = mr.machineid AND mr.isactive = 1
|
||||
LEFT JOIN relationshiptypes rt ON mr.relationshiptypeid = rt.relationshiptypeid AND rt.relationshiptype = 'Controlled By'
|
||||
LEFT JOIN machines m2 ON mr.related_machineid = m2.machineid
|
||||
WHERE m1.pctypeid IS NOT NULL
|
||||
ORDER BY m1.hostname;
|
||||
|
||||
-- vw_pcs_by_hardware: PC counts grouped by manufacturer/model
|
||||
CREATE VIEW vw_pcs_by_hardware AS
|
||||
SELECT
|
||||
COALESCE(v.vendor, 'Unknown') AS manufacturer,
|
||||
COALESCE(md.modelnumber, 'Unknown') AS model,
|
||||
COUNT(m.machineid) AS count,
|
||||
GROUP_CONCAT(DISTINCT pt.typename ORDER BY pt.typename SEPARATOR ', ') AS pc_types
|
||||
FROM machines m
|
||||
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
|
||||
WHERE m.lastupdated > DATE_SUB(NOW(), INTERVAL 30 DAY)
|
||||
AND m.pctypeid IS NOT NULL
|
||||
GROUP BY v.vendor, md.modelnumber
|
||||
ORDER BY COUNT(m.machineid) DESC, v.vendor, md.modelnumber;
|
||||
|
||||
-- vw_shopfloor_comm_config: Shopfloor PCs with communication config
|
||||
CREATE VIEW vw_shopfloor_comm_config AS
|
||||
SELECT
|
||||
m.machineid,
|
||||
m.hostname,
|
||||
m.machinenumber,
|
||||
pt.typename AS pctype,
|
||||
c.address AS ip_address,
|
||||
c.port AS port_or_socket,
|
||||
c.baud,
|
||||
c.databits,
|
||||
c.stopbits,
|
||||
c.parity,
|
||||
ct.typename AS comm_type
|
||||
FROM machines m
|
||||
JOIN pctype pt ON m.pctypeid = pt.pctypeid
|
||||
LEFT JOIN communications c ON m.machineid = c.machineid AND c.isactive = 1
|
||||
LEFT JOIN comstypes ct ON c.comstypeid = ct.comstypeid
|
||||
WHERE pt.typename = 'Shopfloor'
|
||||
AND m.pctypeid IS NOT NULL
|
||||
AND ct.typename IN ('IP', 'Serial')
|
||||
ORDER BY m.machinenumber, m.hostname;
|
||||
|
||||
-- vw_shopfloor_pcs: Shopfloor-type PCs with override support
|
||||
CREATE VIEW vw_shopfloor_pcs AS
|
||||
SELECT
|
||||
m.machineid,
|
||||
m.hostname,
|
||||
m.serialnumber,
|
||||
v.vendor AS manufacturer,
|
||||
md.modelnumber AS model,
|
||||
m.loggedinuser,
|
||||
COALESCE(mo.machinenumber, m.machinenumber) AS machinenumber,
|
||||
COALESCE(os.operatingsystem, 'Unknown') AS operatingsystem,
|
||||
m.lastupdated,
|
||||
m.lastboottime,
|
||||
DATEDIFF(NOW(), m.lastboottime) AS uptime_days
|
||||
FROM machines m
|
||||
JOIN pctype pt ON m.pctypeid = pt.pctypeid
|
||||
LEFT JOIN machineoverrides mo ON m.machineid = mo.machineid
|
||||
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(mo.machinenumber, m.machinenumber), m.hostname;
|
||||
|
||||
-- vw_standard_pcs: Standard-type PCs
|
||||
CREATE VIEW vw_standard_pcs AS
|
||||
SELECT
|
||||
m.machineid,
|
||||
m.hostname,
|
||||
m.serialnumber,
|
||||
v.vendor AS manufacturer,
|
||||
md.modelnumber AS model,
|
||||
m.loggedinuser,
|
||||
m.machinenumber,
|
||||
COALESCE(os.operatingsystem, 'Unknown') AS operatingsystem,
|
||||
m.lastupdated
|
||||
FROM machines m
|
||||
JOIN pctype pt ON m.pctypeid = pt.pctypeid
|
||||
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 = 'Standard'
|
||||
AND m.lastupdated > DATE_SUB(NOW(), INTERVAL 30 DAY)
|
||||
AND m.pctypeid IS NOT NULL
|
||||
ORDER BY m.hostname;
|
||||
|
||||
-- ============================================================================
|
||||
-- STEP 8: Verify
|
||||
-- ============================================================================
|
||||
|
||||
-- Should only show pctype remaining
|
||||
SHOW TABLES LIKE 'pc%';
|
||||
|
||||
-- Verify views work
|
||||
SELECT 'vw_active_pcs' as view_name, COUNT(*) as cnt FROM vw_active_pcs
|
||||
UNION ALL SELECT 'vw_shopfloor_pcs', COUNT(*) FROM vw_shopfloor_pcs
|
||||
UNION ALL SELECT 'vw_standard_pcs', COUNT(*) FROM vw_standard_pcs;
|
||||
|
||||
SELECT 'Migration complete! Legacy pc tables have been dropped.' AS status;
|
||||
Reference in New Issue
Block a user