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:
@@ -1,12 +1,13 @@
|
||||
<%
|
||||
' Use vw_warranty_status view which joins machines with warranties table
|
||||
strSQL2 = "SELECT " & _
|
||||
"COALESCE(SUM(CASE WHEN warrantystatus = 'Active' AND warrantydaysremaining > 90 THEN 1 ELSE 0 END), 0) as active_good, " & _
|
||||
"COALESCE(SUM(CASE WHEN warrantystatus = 'Active' AND warrantydaysremaining BETWEEN 31 AND 90 THEN 1 ELSE 0 END), 0) as active_warning, " & _
|
||||
"COALESCE(SUM(CASE WHEN warrantystatus = 'Active' AND warrantydaysremaining <= 30 AND warrantydaysremaining >= 0 THEN 1 ELSE 0 END), 0) as expiring_soon, " & _
|
||||
"COALESCE(SUM(CASE WHEN warrantystatus = 'Expired' OR warrantydaysremaining < 0 THEN 1 ELSE 0 END), 0) as expired, " & _
|
||||
"COALESCE(SUM(CASE WHEN warrantystatus IS NULL OR warrantystatus = '' THEN 1 ELSE 0 END), 0) as unknown, " & _
|
||||
"COALESCE(SUM(CASE WHEN warrantystatus IS NULL OR warrantystatus = '' OR warrantystatus = 'Unknown' THEN 1 ELSE 0 END), 0) as unknown, " & _
|
||||
"COUNT(*) as total " & _
|
||||
"FROM pc WHERE isactive = 1"
|
||||
"FROM vw_warranty_status"
|
||||
set rswarranty = objconn.Execute(strSQL2)
|
||||
activeGood = CLng(rswarranty("active_good"))
|
||||
activeWarning = CLng(rswarranty("active_warning"))
|
||||
|
||||
@@ -45,7 +45,13 @@
|
||||
newvendorname = Trim(Request.Form("newvendorname"))
|
||||
|
||||
' Validate required fields
|
||||
If Not IsNumeric(printerid) Or CLng(printerid) < 1 Then
|
||||
If printerid = "" Or Not IsNumeric(printerid) Then
|
||||
objConn.Close
|
||||
Response.Redirect("displayprinters.asp?error=INVALID_PRINTER_ID")
|
||||
Response.End
|
||||
End If
|
||||
|
||||
If CLng(printerid) < 1 Then
|
||||
objConn.Close
|
||||
Response.Redirect("displayprinters.asp?error=INVALID_PRINTER_ID")
|
||||
Response.End
|
||||
|
||||
@@ -37,7 +37,10 @@ End If
|
||||
<h5 class="logo-text">West Jefferson</h5>
|
||||
</a>
|
||||
</div>
|
||||
<div style="font-size: 10px; color: #888; text-align: center; padding-bottom: 8px;">Fiscal Week <%=fiscalWeek%></div>
|
||||
<div style="padding: 10px 0; background: #2a2a2a; border-top: 1px solid #3a3a3a; border-bottom: 1px solid #3a3a3a; text-align: center;">
|
||||
<span style="font-size: 10px; color: #888; text-transform: uppercase; letter-spacing: 1px;">Fiscal Week</span>
|
||||
<div style="font-size: 22px; font-weight: 600; color: #fff;"><%=fiscalWeek%></div>
|
||||
</div>
|
||||
<ul class="sidebar-menu do-nicescrol">
|
||||
<li class="sidebar-header">MAIN NAVIGATION</li>
|
||||
<li>
|
||||
@@ -88,7 +91,6 @@ End If
|
||||
<li><a href="./displayusb.asp"><i class="zmdi zmdi-usb text-purple"></i><span>USB Devices</span></a></li>
|
||||
<li><a href="./displaynotifications.asp"><i class="zmdi zmdi zmdi-notifications-none text-success"></i><span>Notifications</span></a></li>
|
||||
<li><a href="./tv-dashboard/" target="_blank"><i class="zmdi zmdi-tv text-warning"></i><span>Lobby Display</span></a></li>
|
||||
<li><a href="javaScript:void();"><i class="zmdi zmdi-share text-info"></i> <span>Information</span></a></li>
|
||||
|
||||
</ul>
|
||||
|
||||
|
||||
@@ -1,26 +1,4 @@
|
||||
<%
|
||||
'=============================================================================
|
||||
' SUBROUTINE: AutoDeactivateExpiredNotifications
|
||||
' PURPOSE: Automatically deactivate notifications where endtime has passed
|
||||
'
|
||||
' LOGIC:
|
||||
' - Find all active notifications where endtime < NOW() (expired)
|
||||
' - Set isactive = 0 for those notifications
|
||||
' - This provides automatic cleanup without manual intervention
|
||||
'
|
||||
' RUNS: On every page load (minimal performance impact - simple UPDATE query)
|
||||
'=============================================================================
|
||||
Sub AutoDeactivateExpiredNotifications()
|
||||
On Error Resume Next
|
||||
Dim strAutoDeactivate
|
||||
strAutoDeactivate = "UPDATE notifications SET isactive = 0 " & _
|
||||
"WHERE isactive = 1 " & _
|
||||
"AND endtime IS NOT NULL " & _
|
||||
"AND endtime < NOW()"
|
||||
objConn.Execute strAutoDeactivate
|
||||
On Error Goto 0
|
||||
End Sub
|
||||
|
||||
' objConn - script-global connection object (no Dim for global scope)
|
||||
Session.Timeout=15
|
||||
Set objConn=Server.CreateObject("ADODB.Connection")
|
||||
@@ -37,8 +15,4 @@ End Sub
|
||||
"Pooling=True;Max Pool Size=100;"
|
||||
objConn.Open
|
||||
set rs = server.createobject("ADODB.Recordset")
|
||||
|
||||
' Auto-deactivate expired notifications
|
||||
' This runs on every page load to ensure notifications with past endtime are automatically disabled
|
||||
Call AutoDeactivateExpiredNotifications()
|
||||
%>
|
||||
@@ -1,185 +0,0 @@
|
||||
<%@ Language=VBScript %>
|
||||
<!--#include file="../includes/sql.asp"-->
|
||||
<%
|
||||
' ============================================================================
|
||||
' API Endpoint: Get Notifications (Safe Version with Parameterized Query)
|
||||
' Returns current and upcoming notifications in JSON format
|
||||
' Uses shared sql.asp connection from shopdb project
|
||||
' ============================================================================
|
||||
|
||||
Option Explicit
|
||||
Response.ContentType = "application/json"
|
||||
Response.Charset = "UTF-8"
|
||||
|
||||
Dim objCmd, objRS
|
||||
Dim now, future
|
||||
Dim currentEvents(), upcomingEvents()
|
||||
Dim currentCount, upcomingCount
|
||||
Dim jsonOutput
|
||||
|
||||
' Initialize
|
||||
currentCount = 0
|
||||
upcomingCount = 0
|
||||
ReDim currentEvents(0)
|
||||
ReDim upcomingEvents(0)
|
||||
|
||||
On Error Resume Next
|
||||
|
||||
' Calculate time window
|
||||
now = Now()
|
||||
future = DateAdd("h", 72, now)
|
||||
|
||||
' objConn is already created and opened by includes/sql.asp
|
||||
' No need to create our own connection
|
||||
|
||||
' Create command with parameters
|
||||
Set objCmd = Server.CreateObject("ADODB.Command")
|
||||
Set objCmd.ActiveConnection = objConn
|
||||
objCmd.CommandText = "SELECT n.notificationid, n.notification, n.starttime, n.endtime, " & _
|
||||
"n.ticketnumber, n.link, n.isactive, n.isshopfloor, " & _
|
||||
"nt.typename, nt.typecolor " & _
|
||||
"FROM notifications n " & _
|
||||
"LEFT JOIN notificationtypes nt ON n.notificationtypeid = nt.notificationtypeid " & _
|
||||
"WHERE n.isactive = 1 AND n.isshopfloor = 1 " & _
|
||||
"AND ((n.starttime <= ? AND (n.endtime IS NULL OR n.endtime >= ?)) " & _
|
||||
" OR (n.starttime BETWEEN ? AND ?)) " & _
|
||||
"ORDER BY n.starttime ASC"
|
||||
|
||||
objCmd.CommandType = 1 ' adCmdText
|
||||
|
||||
' Add parameters
|
||||
objCmd.Parameters.Append objCmd.CreateParameter("future1", 135, 1, , future) ' adDBTimeStamp
|
||||
objCmd.Parameters.Append objCmd.CreateParameter("now1", 135, 1, , now)
|
||||
objCmd.Parameters.Append objCmd.CreateParameter("now2", 135, 1, , now)
|
||||
objCmd.Parameters.Append objCmd.CreateParameter("future2", 135, 1, , future)
|
||||
|
||||
Set objRS = objCmd.Execute
|
||||
|
||||
If Err.Number <> 0 Then
|
||||
Response.Write "{""success"":false,""error"":""Query error: " & EscapeJSON(Err.Description) & """}"
|
||||
Response.End
|
||||
End If
|
||||
|
||||
' Process records
|
||||
Do While Not objRS.EOF
|
||||
Dim startTime, endTime, isCurrent
|
||||
|
||||
startTime = objRS("starttime")
|
||||
endTime = objRS("endtime")
|
||||
|
||||
' Check if current
|
||||
isCurrent = False
|
||||
If IsDate(startTime) And startTime <= now Then
|
||||
If IsNull(endTime) Or endTime >= now Then
|
||||
isCurrent = True
|
||||
End If
|
||||
End If
|
||||
|
||||
' Build event object
|
||||
Dim eventObj
|
||||
Set eventObj = BuildEventJSON(objRS)
|
||||
|
||||
' Add to appropriate array
|
||||
If isCurrent Then
|
||||
ReDim Preserve currentEvents(currentCount)
|
||||
currentEvents(currentCount) = eventObj
|
||||
currentCount = currentCount + 1
|
||||
Else
|
||||
ReDim Preserve upcomingEvents(upcomingCount)
|
||||
upcomingEvents(upcomingCount) = eventObj
|
||||
upcomingCount = upcomingCount + 1
|
||||
End If
|
||||
|
||||
objRS.MoveNext
|
||||
Loop
|
||||
|
||||
objRS.Close
|
||||
' objConn is managed by sql.asp - don't close it here
|
||||
|
||||
' Build JSON response
|
||||
jsonOutput = "{""success"":true," & _
|
||||
"""timestamp"":""" & ISO8601(Now()) & """," & _
|
||||
"""current"":[" & JoinArray(currentEvents, currentCount) & "]," & _
|
||||
"""upcoming"":[" & JoinArray(upcomingEvents, upcomingCount) & "]}"
|
||||
|
||||
Response.Write jsonOutput
|
||||
|
||||
' ============================================================================
|
||||
' Functions
|
||||
' ============================================================================
|
||||
|
||||
Function BuildEventJSON(rs)
|
||||
Dim json
|
||||
json = "{" & _
|
||||
"""notificationid"":" & rs("notificationid") & "," & _
|
||||
"""notification"":""" & EscapeJSON(rs("notification")) & """," & _
|
||||
"""starttime"":""" & ISO8601(rs("starttime")) & """," & _
|
||||
"""endtime"":" & NullOrString(rs("endtime")) & "," & _
|
||||
"""ticketnumber"":" & NullOrString(rs("ticketnumber")) & "," & _
|
||||
"""link"":" & NullOrString(rs("link")) & "," & _
|
||||
"""isactive"":" & BoolStr(rs("isactive")) & "," & _
|
||||
"""isshopfloor"":" & BoolStr(rs("isshopfloor")) & "," & _
|
||||
"""typename"":""" & EscapeJSON(rs("typename")) & """," & _
|
||||
"""typecolor"":""" & EscapeJSON(rs("typecolor")) & """" & _
|
||||
"}"
|
||||
BuildEventJSON = json
|
||||
End Function
|
||||
|
||||
Function JoinArray(arr, count)
|
||||
If count = 0 Then
|
||||
JoinArray = ""
|
||||
Exit Function
|
||||
End If
|
||||
Dim i, result
|
||||
result = ""
|
||||
For i = 0 To count - 1
|
||||
If i > 0 Then result = result & ","
|
||||
result = result & arr(i)
|
||||
Next
|
||||
JoinArray = result
|
||||
End Function
|
||||
|
||||
Function EscapeJSON(str)
|
||||
If IsNull(str) Then
|
||||
EscapeJSON = ""
|
||||
Exit Function
|
||||
End If
|
||||
Dim result
|
||||
result = CStr(str)
|
||||
result = Replace(result, "\", "\\")
|
||||
result = Replace(result, """", "\""")
|
||||
result = Replace(result, Chr(13), "\r")
|
||||
result = Replace(result, Chr(10), "\n")
|
||||
result = Replace(result, Chr(9), "\t")
|
||||
EscapeJSON = result
|
||||
End Function
|
||||
|
||||
Function ISO8601(dt)
|
||||
If IsNull(dt) Or Not IsDate(dt) Then
|
||||
ISO8601 = ""
|
||||
Exit Function
|
||||
End If
|
||||
ISO8601 = Year(dt) & "-" & _
|
||||
Right("0" & Month(dt), 2) & "-" & _
|
||||
Right("0" & Day(dt), 2) & "T" & _
|
||||
Right("0" & Hour(dt), 2) & ":" & _
|
||||
Right("0" & Minute(dt), 2) & ":" & _
|
||||
Right("0" & Second(dt), 2)
|
||||
End Function
|
||||
|
||||
Function NullOrString(val)
|
||||
If IsNull(val) Then
|
||||
NullOrString = "null"
|
||||
Else
|
||||
NullOrString = """" & EscapeJSON(val) & """"
|
||||
End If
|
||||
End Function
|
||||
|
||||
Function BoolStr(val)
|
||||
If CBool(val) Then
|
||||
BoolStr = "true"
|
||||
Else
|
||||
BoolStr = "false"
|
||||
End If
|
||||
End Function
|
||||
%>
|
||||
@@ -1109,7 +1109,7 @@
|
||||
}
|
||||
|
||||
try {
|
||||
const response = await fetch('../api_businessunits.asp');
|
||||
const response = await fetch('../apibusinessunits.asp');
|
||||
if (!response.ok) {
|
||||
throw new Error(`HTTP error! status: ${response.status}`);
|
||||
}
|
||||
@@ -1147,7 +1147,7 @@
|
||||
// Fetch notifications from API
|
||||
async function fetchNotifications() {
|
||||
try {
|
||||
let url = '../api_shopfloor.asp';
|
||||
let url = '../apishopfloor.asp';
|
||||
if (selectedBusinessUnit) {
|
||||
url += '?businessunit=' + encodeURIComponent(selectedBusinessUnit);
|
||||
}
|
||||
|
||||
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;
|
||||
@@ -92,7 +92,7 @@
|
||||
// Fetch slides from API
|
||||
async function fetchSlides() {
|
||||
try {
|
||||
const response = await fetch('api_slides.asp');
|
||||
const response = await fetch('apislides.asp');
|
||||
if (!response.ok) throw new Error('API error');
|
||||
|
||||
const data = await response.json();
|
||||
|
||||
Reference in New Issue
Block a user