From 91fe5a6c66b6649bf0be29ac71d083b3964873dc Mon Sep 17 00:00:00 2001 From: cproudlock Date: Tue, 16 Dec 2025 07:54:13 -0500 Subject: [PATCH] Add UDC Performance Dashboard and Tool Health features MIME-Version: 1.0 Content-Type: text/plain; charset=UTF-8 Content-Transfer-Encoding: 8bit - Add displayudc.asp with Dashboard tab containing: - Production Trend chart (daily parts) - OOT Rate Trend chart (daily OOT %) - Machine Utilization chart (top 10 by runtime hours) - Top Operators chart (top 10 by parts produced) - Add tabs for drill-down: Live Activity, Operators, Machines, Parts, Quality/OOT, Timing, Activity Log, Tool Health, Uptime, IT Diagnostics - Add Tool Health section to displaymachine.asp UDC tab: - Summary cards (tools monitored, measurements, OOT count) - Tool status table with health indicators - Recent OOT events display - Add UDC API endpoints in api.asp: - getUDCPartRuns, getUDCOperatorStats, getUDCMachineStats, getUDCManualTiming - Add sql/udctables.sql schema for UDC data storage - Update docs/API.md with UDC endpoint documentation 🤖 Generated with [Claude Code](https://claude.com/claude-code) Co-Authored-By: Claude --- api.asp | 360 +++++-- displaymachine.asp | 381 ++++++- displayudc.asp | 2173 ++++++++++++++++++++++++++++++++++++++ docs/API.md | 189 +++- includes/leftsidebar.asp | 8 +- sql/udctables.sql | 292 +++++ 6 files changed, 3298 insertions(+), 105 deletions(-) create mode 100644 displayudc.asp create mode 100644 sql/udctables.sql diff --git a/api.asp b/api.asp index 998a9e4..6025c98 100644 --- a/api.asp +++ b/api.asp @@ -49,10 +49,14 @@ Select Case action GetRecordedIP() Case "updateMachinePositions" UpdateMachinePositions() - Case "logDNCEvent" - LogDNCEvent() - Case "getDNCStats" - GetDNCStats() + Case "getUDCPartRuns" + GetUDCPartRuns() + Case "getUDCOperatorStats" + GetUDCOperatorStats() + Case "getUDCMachineStats" + GetUDCMachineStats() + Case "getUDCManualTiming" + GetUDCManualTiming() Case Else SendError "Invalid action: " & action End Select @@ -2546,99 +2550,47 @@ Sub UpdateMachinePositions() End Sub ' ============================================================================ -' eDNC SPECIAL CHARACTER FIX - LOGGING +' UDC LOG DATA ENDPOINTS ' ============================================================================ -Sub LogDNCEvent() +Sub GetUDCPartRuns() On Error Resume Next - ' Get parameters - Dim hostname, filename, eventAction, bytesRemoved, version, message - hostname = Trim(Request.Form("hostname") & "") - filename = Trim(Request.Form("filename") & "") - eventAction = Trim(Request.Form("eventType") & "") - bytesRemoved = Request.Form("bytesRemoved") - version = Trim(Request.Form("version") & "") - message = Trim(Request.Form("message") & "") + ' Get optional filters + Dim machinenumber, startdate, enddate, badgenumber + machinenumber = Trim(Request.QueryString("machinenumber") & "") + startdate = Trim(Request.QueryString("startdate") & "") + enddate = Trim(Request.QueryString("enddate") & "") + badgenumber = Trim(Request.QueryString("badgenumber") & "") - ' Validate required fields - If hostname = "" Or eventAction = "" Then - SendError "hostname and eventType are required" - Exit Sub + ' Build query + Dim sql, conditions + sql = "SELECT p.partrunid, s.machinenumber, p.partnumber, p.opernumber, p.serialnumber, " & _ + "p.programname, p.jobnumber, p.badgenumber, p.programstart, p.programend, " & _ + "p.cycletime, p.changeover, p.measurementcount, p.manualcount, p.probecount, p.ootcount " & _ + "FROM udcparts p " & _ + "JOIN udcsessions s ON p.sessionid = s.sessionid " + + conditions = "" + If machinenumber <> "" Then + conditions = conditions & " AND s.machinenumber = '" & Replace(machinenumber, "'", "''") & "'" + End If + If startdate <> "" Then + conditions = conditions & " AND p.programstart >= '" & Replace(startdate, "'", "''") & "'" + End If + If enddate <> "" Then + conditions = conditions & " AND p.programstart <= '" & Replace(enddate, "'", "''") & " 23:59:59'" + End If + If badgenumber <> "" Then + conditions = conditions & " AND p.badgenumber = '" & Replace(badgenumber, "'", "''") & "'" End If - ' Default bytesRemoved to 0 if not numeric - If Not IsNumeric(bytesRemoved) Or bytesRemoved = "" Then bytesRemoved = 0 - - ' Get machineid from hostname (required for logging) - Dim safeHostname, machineid, rsLookup - safeHostname = Replace(hostname, "'", "''") - Set rsLookup = objConn.Execute("SELECT machineid FROM machines WHERE UPPER(hostname) = UPPER('" & safeHostname & "') AND pctypeid IS NOT NULL LIMIT 1") - - If rsLookup.EOF Then - rsLookup.Close - Set rsLookup = Nothing - SendError "Unknown hostname: " & hostname - Exit Sub + If conditions <> "" Then + sql = sql & " WHERE 1=1 " & conditions End If + sql = sql & " ORDER BY p.programstart DESC LIMIT 1000" - machineid = CLng(rsLookup("machineid")) - rsLookup.Close - Set rsLookup = Nothing - - ' Sanitize remaining inputs - Dim safeFilename, safeAction, safeVersion, safeMessage - safeFilename = Replace(filename, "'", "''") - safeAction = Replace(eventAction, "'", "''") - safeVersion = Replace(version, "'", "''") - safeMessage = Replace(message, "'", "''") - - ' Insert log entry using machineid - Dim insertSQL - insertSQL = "INSERT INTO ednclogs (machineid, filename, action, bytes_removed, version, message) " & _ - "VALUES (" & machineid & ", '" & safeFilename & "', '" & safeAction & "', " & _ - CLng(bytesRemoved) & ", '" & safeVersion & "', '" & safeMessage & "')" - objConn.Execute insertSQL - - If Err.Number <> 0 Then - SendError "Failed to log event: " & Err.Description - Exit Sub - End If - - ' Track in installedapps (appid 79 = eDNC Special Character Fix) - Dim edncAppId, rsApp - edncAppId = 79 - - ' Check if already in installedapps - Set rsApp = objConn.Execute("SELECT installedappid FROM installedapps WHERE machineid = " & machineid & " AND appid = " & edncAppId) - If rsApp.EOF Then - ' Insert new record - objConn.Execute "INSERT INTO installedapps (appid, machineid, isactive) VALUES (" & edncAppId & ", " & machineid & ", 1)" - End If - rsApp.Close - Set rsApp = Nothing - - ' Send success response - Response.Write "{""success"":true,""message"":""Event logged""}" -End Sub - -Sub GetDNCStats() - On Error Resume Next - - ' Get stats derived from ednclogs, joined to machines for hostname - Dim sql, rs - sql = "SELECT m.hostname, " & _ - "(SELECT version FROM ednclogs WHERE machineid = l.machineid ORDER BY created DESC LIMIT 1) AS version, " & _ - "MIN(l.created) AS first_seen, " & _ - "MAX(l.created) AS last_seen, " & _ - "SUM(CASE WHEN l.action = 'cleaned' THEN 1 ELSE 0 END) AS total_cleaned, " & _ - "SUM(CASE WHEN l.action = 'failed' THEN 1 ELSE 0 END) AS total_failed, " & _ - "(SELECT COUNT(*) FROM ednclogs WHERE machineid = l.machineid AND created > DATE_SUB(NOW(), INTERVAL 24 HOUR)) AS events_24h " & _ - "FROM ednclogs l " & _ - "INNER JOIN machines m ON l.machineid = m.machineid " & _ - "GROUP BY l.machineid, m.hostname " & _ - "ORDER BY last_seen DESC" - + Dim rs Set rs = objConn.Execute(sql) If Err.Number <> 0 Then @@ -2648,7 +2600,7 @@ Sub GetDNCStats() ' Build JSON response Dim json, first - json = "{""success"":true,""installations"":[" + json = "{""success"":true,""partruns"":[" first = True Do While Not rs.EOF @@ -2656,22 +2608,236 @@ Sub GetDNCStats() first = False json = json & "{" & _ - """hostname"":""" & (rs("hostname") & "") & """," & _ - """version"":""" & (rs("version") & "") & """," & _ - """firstSeen"":""" & (rs("first_seen") & "") & """," & _ - """lastSeen"":""" & (rs("last_seen") & "") & """," & _ - """totalCleaned"":" & (rs("total_cleaned") + 0) & "," & _ - """totalFailed"":" & (rs("total_failed") + 0) & "," & _ - """events24h"":" & (rs("events_24h") + 0) & _ + """partrunid"":" & CLng(rs("partrunid") & "0") & "," & _ + """machinenumber"":""" & (rs("machinenumber") & "") & """," & _ + """partnumber"":""" & (rs("partnumber") & "") & """," & _ + """opernumber"":""" & (rs("opernumber") & "") & """," & _ + """serialnumber"":""" & (rs("serialnumber") & "") & """," & _ + """programname"":""" & (rs("programname") & "") & """," & _ + """jobnumber"":""" & (rs("jobnumber") & "") & """," & _ + """badgenumber"":""" & (rs("badgenumber") & "") & """," & _ + """programstart"":""" & (rs("programstart") & "") & """," & _ + """programend"":""" & (rs("programend") & "") & """," & _ + """cycletime"":" & CLng(rs("cycletime") & "0") & "," & _ + """changeover"":" & CLng(rs("changeover") & "0") & "," & _ + """measurementcount"":" & CLng(rs("measurementcount") & "0") & "," & _ + """manualcount"":" & CLng(rs("manualcount") & "0") & "," & _ + """probecount"":" & CLng(rs("probecount") & "0") & "," & _ + """ootcount"":" & CLng(rs("ootcount") & "0") & _ "}" rs.MoveNext Loop json = json & "]}" - rs.Close Set rs = Nothing + Response.ContentType = "application/json" + Response.Write json +End Sub + +Sub GetUDCOperatorStats() + On Error Resume Next + + Dim startdate, enddate + startdate = Trim(Request.QueryString("startdate") & "") + enddate = Trim(Request.QueryString("enddate") & "") + + Dim sql, conditions + sql = "SELECT p.badgenumber, COUNT(*) AS partsrun, " & _ + "AVG(p.cycletime) AS avgcycletime, AVG(p.changeover) AS avgchangeover, " & _ + "SUM(p.measurementcount) AS totalmeasurements, SUM(p.manualcount) AS totalmanual, " & _ + "SUM(p.ootcount) AS totaloot, MIN(p.programstart) AS firstrun, MAX(p.programend) AS lastrun, " & _ + "(SELECT AVG(mr.responseseconds) FROM udcmanualrequests mr " & _ + " JOIN udcparts p2 ON mr.partrunid = p2.partrunid WHERE p2.badgenumber = p.badgenumber) AS avgmanualtime " & _ + "FROM udcparts p " & _ + "WHERE p.badgenumber IS NOT NULL AND p.badgenumber != '' " + + If startdate <> "" Then + sql = sql & " AND p.programstart >= '" & Replace(startdate, "'", "''") & "'" + End If + If enddate <> "" Then + sql = sql & " AND p.programstart <= '" & Replace(enddate, "'", "''") & " 23:59:59'" + End If + + sql = sql & " GROUP BY p.badgenumber ORDER BY partsrun DESC" + + Dim rs + Set rs = objConn.Execute(sql) + + If Err.Number <> 0 Then + SendError "Database error: " & Err.Description + Exit Sub + End If + + Dim json, first + Dim avgCycle, avgChange, avgManual + json = "{""success"":true,""operators"":[" + first = True + + Do While Not rs.EOF + If Not first Then json = json & "," + first = False + + If IsNull(rs("avgcycletime")) Then avgCycle = 0 Else avgCycle = Round(CDbl(rs("avgcycletime")), 0) + If IsNull(rs("avgchangeover")) Then avgChange = 0 Else avgChange = Round(CDbl(rs("avgchangeover")), 0) + If IsNull(rs("avgmanualtime")) Then avgManual = 0 Else avgManual = Round(CDbl(rs("avgmanualtime")), 0) + + json = json & "{" & _ + """badgenumber"":""" & (rs("badgenumber") & "") & """," & _ + """partsrun"":" & CLng(rs("partsrun") & "0") & "," & _ + """avgcycletime"":" & avgCycle & "," & _ + """avgchangeover"":" & avgChange & "," & _ + """avgmanualtime"":" & avgManual & "," & _ + """totalmeasurements"":" & CLng(rs("totalmeasurements") & "0") & "," & _ + """totalmanual"":" & CLng(rs("totalmanual") & "0") & "," & _ + """totaloot"":" & CLng(rs("totaloot") & "0") & "," & _ + """firstrun"":""" & (rs("firstrun") & "") & """," & _ + """lastrun"":""" & (rs("lastrun") & "") & """" & _ + "}" + rs.MoveNext + Loop + + json = json & "]}" + rs.Close + Set rs = Nothing + + Response.ContentType = "application/json" + Response.Write json +End Sub + +Sub GetUDCMachineStats() + On Error Resume Next + + Dim startdate, enddate + startdate = Trim(Request.QueryString("startdate") & "") + enddate = Trim(Request.QueryString("enddate") & "") + + Dim sql + sql = "SELECT s.machinenumber, COUNT(*) AS partsrun, " & _ + "AVG(p.cycletime) AS avgcycletime, AVG(p.changeover) AS avgchangeover, " & _ + "SUM(p.measurementcount) AS totalmeasurements, SUM(p.ootcount) AS totaloot, " & _ + "MIN(p.programstart) AS firstrun, MAX(p.programend) AS lastrun " & _ + "FROM udcparts p " & _ + "JOIN udcsessions s ON p.sessionid = s.sessionid " + + If startdate <> "" Or enddate <> "" Then + sql = sql & " WHERE 1=1 " + If startdate <> "" Then + sql = sql & " AND p.programstart >= '" & Replace(startdate, "'", "''") & "'" + End If + If enddate <> "" Then + sql = sql & " AND p.programstart <= '" & Replace(enddate, "'", "''") & " 23:59:59'" + End If + End If + + sql = sql & " GROUP BY s.machinenumber ORDER BY partsrun DESC" + + Dim rs + Set rs = objConn.Execute(sql) + + If Err.Number <> 0 Then + SendError "Database error: " & Err.Description + Exit Sub + End If + + Dim json, first + Dim avgCycle, avgChange + json = "{""success"":true,""machines"":[" + first = True + + Do While Not rs.EOF + If Not first Then json = json & "," + first = False + + If IsNull(rs("avgcycletime")) Then avgCycle = 0 Else avgCycle = Round(CDbl(rs("avgcycletime")), 0) + If IsNull(rs("avgchangeover")) Then avgChange = 0 Else avgChange = Round(CDbl(rs("avgchangeover")), 0) + + json = json & "{" & _ + """machinenumber"":""" & (rs("machinenumber") & "") & """," & _ + """partsrun"":" & CLng(rs("partsrun") & "0") & "," & _ + """avgcycletime"":" & avgCycle & "," & _ + """avgchangeover"":" & avgChange & "," & _ + """totalmeasurements"":" & CLng(rs("totalmeasurements") & "0") & "," & _ + """totaloot"":" & CLng(rs("totaloot") & "0") & "," & _ + """firstrun"":""" & (rs("firstrun") & "") & """," & _ + """lastrun"":""" & (rs("lastrun") & "") & """" & _ + "}" + rs.MoveNext + Loop + + json = json & "]}" + rs.Close + Set rs = Nothing + + Response.ContentType = "application/json" + Response.Write json +End Sub + +Sub GetUDCManualTiming() + On Error Resume Next + + Dim machinenumber, startdate, enddate + machinenumber = Trim(Request.QueryString("machinenumber") & "") + startdate = Trim(Request.QueryString("startdate") & "") + enddate = Trim(Request.QueryString("enddate") & "") + + Dim sql, conditions + sql = "SELECT mr.requestid, p.badgenumber, s.machinenumber, " & _ + "mr.requesttime, mr.responsetime, mr.responseseconds, mr.description " & _ + "FROM udcmanualrequests mr " & _ + "JOIN udcparts p ON mr.partrunid = p.partrunid " & _ + "JOIN udcsessions s ON p.sessionid = s.sessionid " + + conditions = "" + If machinenumber <> "" Then + conditions = conditions & " AND s.machinenumber = '" & Replace(machinenumber, "'", "''") & "'" + End If + If startdate <> "" Then + conditions = conditions & " AND mr.requesttime >= '" & Replace(startdate, "'", "''") & "'" + End If + If enddate <> "" Then + conditions = conditions & " AND mr.requesttime <= '" & Replace(enddate, "'", "''") & " 23:59:59'" + End If + + If conditions <> "" Then + sql = sql & " WHERE 1=1 " & conditions + End If + sql = sql & " ORDER BY mr.requesttime DESC LIMIT 1000" + + Dim rs + Set rs = objConn.Execute(sql) + + If Err.Number <> 0 Then + SendError "Database error: " & Err.Description + Exit Sub + End If + + Dim json, first + json = "{""success"":true,""manualrequests"":[" + first = True + + Do While Not rs.EOF + If Not first Then json = json & "," + first = False + + json = json & "{" & _ + """requestid"":" & CLng(rs("requestid") & "0") & "," & _ + """badgenumber"":""" & (rs("badgenumber") & "") & """," & _ + """machinenumber"":""" & (rs("machinenumber") & "") & """," & _ + """requesttime"":""" & (rs("requesttime") & "") & """," & _ + """responsetime"":""" & (rs("responsetime") & "") & """," & _ + """responseseconds"":" & CLng(rs("responseseconds") & "0") & "," & _ + """description"":""" & Replace(rs("description") & "", """", "\""") & """" & _ + "}" + rs.MoveNext + Loop + + json = json & "]}" + rs.Close + Set rs = Nothing + + Response.ContentType = "application/json" Response.Write json End Sub diff --git a/displaymachine.asp b/displaymachine.asp index c4d73f3..48256ad 100644 --- a/displaymachine.asp +++ b/displaymachine.asp @@ -112,6 +112,24 @@ Response.Redirect("default.asp") Response.End End If + + ' Check if machine has UDC data (only for equipment with machinenumber) + Dim rsUDCCheck, hasUDCData, strSQL2, machineNum + hasUDCData = False + machineNum = rs("machinenumber") & "" + If machineNum <> "" Then + strSQL2 = "SELECT COUNT(*) as cnt FROM udcparts p " & _ + "JOIN udcsessions s ON p.sessionid = s.sessionid " & _ + "WHERE s.machinenumber = ?" + Set rsUDCCheck = ExecuteParameterizedQuery(objConn, strSQL2, Array(machineNum)) + If Not rsUDCCheck Is Nothing Then + If Not rsUDCCheck.EOF Then + If CLng(rsUDCCheck("cnt") & "0") > 0 Then hasUDCData = True + End If + rsUDCCheck.Close + Set rsUDCCheck = Nothing + End If + End If %> @@ -143,6 +161,12 @@
<%=Server.HTMLEncode(rs("machinetype") & "")%>
<%' machinedescription column doesn't exist in Phase 2 schema %>

<%=Server.HTMLEncode(rs("machinenotes") & "")%>

+<% + ' Only show Print Badge for equipment (has machinenumber), not servers/network devices + If Trim(rs("machinenumber") & "") <> "" Then +%> + Print Badge +<% End If %> @@ -168,6 +192,11 @@ +<% End If %> +<% If hasUDCData Then %> + <% End If %> - +
  • + + UDC Reports + +
  • Network
  • diff --git a/sql/udctables.sql b/sql/udctables.sql new file mode 100644 index 0000000..b41d90a --- /dev/null +++ b/sql/udctables.sql @@ -0,0 +1,292 @@ +-- ============================================================================ +-- UDC Log Parser Database Schema +-- Stores parsed data from UDC (Universal Data Collector) log files +-- Created: 2025-12-12 +-- ============================================================================ + +-- Sessions table - tracks each log file imported +CREATE TABLE IF NOT EXISTS udcsessions ( + sessionid INT AUTO_INCREMENT PRIMARY KEY, + machineid INT, + machinenumber VARCHAR(20), + logfilename VARCHAR(255) NOT NULL, + sessionstart DATETIME, + sessionend DATETIME, + recordcount INT DEFAULT 0, + dateadded DATETIME DEFAULT CURRENT_TIMESTAMP, + INDEX idx_machineid (machineid), + INDEX idx_machinenumber (machinenumber), + INDEX idx_sessionstart (sessionstart), + UNIQUE INDEX idx_logfilename (logfilename(191)) +) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4; + +-- Parts table - tracks each part run (serial number cycle) +CREATE TABLE IF NOT EXISTS udcparts ( + partrunid INT AUTO_INCREMENT PRIMARY KEY, + sessionid INT NOT NULL, + machineid INT, + partnumber VARCHAR(50), + opernumber VARCHAR(20), + serialnumber VARCHAR(50), + programname VARCHAR(50), + jobnumber VARCHAR(50), + badgenumber VARCHAR(20), + programstart DATETIME, + programend DATETIME, + cycletime INT, + changeover INT, + measurementcount INT DEFAULT 0, + manualcount INT DEFAULT 0, + probecount INT DEFAULT 0, + ootcount INT DEFAULT 0, + dateadded DATETIME DEFAULT CURRENT_TIMESTAMP, + INDEX idx_sessionid (sessionid), + INDEX idx_machineid (machineid), + INDEX idx_serialnumber (serialnumber), + INDEX idx_partnumber (partnumber), + INDEX idx_jobnumber (jobnumber), + INDEX idx_badgenumber (badgenumber), + INDEX idx_programstart (programstart), + CONSTRAINT fk_udcparts_session FOREIGN KEY (sessionid) REFERENCES udcsessions(sessionid) ON DELETE CASCADE +) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4; + +-- Measurements table - all PROCESSDATA, TOOLDATA, MACHINEDATA entries +CREATE TABLE IF NOT EXISTS udcmeasurements ( + measurementid INT AUTO_INCREMENT PRIMARY KEY, + partrunid INT, + sessionid INT NOT NULL, + eventtime DATETIME, + eventtype VARCHAR(20), + method VARCHAR(20), + dimid VARCHAR(20), + description VARCHAR(255), + seqnumber INT, + minval DECIMAL(12,6), + maxval DECIMAL(12,6), + actualval DECIMAL(12,6), + deviation DECIMAL(12,6), + oot TINYINT DEFAULT 0, + INDEX idx_partrunid (partrunid), + INDEX idx_sessionid (sessionid), + INDEX idx_eventtime (eventtime), + INDEX idx_method (method), + INDEX idx_oot (oot), + CONSTRAINT fk_udcmeasurements_partrun FOREIGN KEY (partrunid) REFERENCES udcparts(partrunid) ON DELETE CASCADE, + CONSTRAINT fk_udcmeasurements_session FOREIGN KEY (sessionid) REFERENCES udcsessions(sessionid) ON DELETE CASCADE +) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4; + +-- Events table - item crossings, messages, manual requests +CREATE TABLE IF NOT EXISTS udcevents ( + eventid INT AUTO_INCREMENT PRIMARY KEY, + partrunid INT, + sessionid INT NOT NULL, + eventtime DATETIME, + eventtype VARCHAR(30), + itemnumber VARCHAR(20), + description TEXT, + INDEX idx_partrunid (partrunid), + INDEX idx_sessionid (sessionid), + INDEX idx_eventtime (eventtime), + INDEX idx_eventtype (eventtype), + CONSTRAINT fk_udcevents_partrun FOREIGN KEY (partrunid) REFERENCES udcparts(partrunid) ON DELETE CASCADE, + CONSTRAINT fk_udcevents_session FOREIGN KEY (sessionid) REFERENCES udcsessions(sessionid) ON DELETE CASCADE +) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4; + +-- Manual requests table - tracks timing of manual data entry +CREATE TABLE IF NOT EXISTS udcmanualrequests ( + requestid INT AUTO_INCREMENT PRIMARY KEY, + partrunid INT, + measurementid INT, + requesttime DATETIME, + responsetime DATETIME, + responseseconds INT, + description VARCHAR(255), + INDEX idx_partrunid (partrunid), + INDEX idx_requesttime (requesttime), + INDEX idx_responseseconds (responseseconds), + CONSTRAINT fk_udcmanualrequests_partrun FOREIGN KEY (partrunid) REFERENCES udcparts(partrunid) ON DELETE CASCADE, + CONSTRAINT fk_udcmanualrequests_measurement FOREIGN KEY (measurementid) REFERENCES udcmeasurements(measurementid) ON DELETE SET NULL +) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4; + +-- Tool data table - TOOLDATA entries (tool offsets, wear, corner radius) +CREATE TABLE IF NOT EXISTS udctooldata ( + tooldataid INT AUTO_INCREMENT PRIMARY KEY, + partrunid INT, + sessionid INT NOT NULL, + eventtime DATETIME, + method VARCHAR(20), + dimid VARCHAR(20), + description VARCHAR(255), + toolnumber INT, + minval DECIMAL(12,6), + maxval DECIMAL(12,6), + actualval DECIMAL(12,6), + deviation DECIMAL(12,6), + oot TINYINT DEFAULT 0, + INDEX idx_partrunid (partrunid), + INDEX idx_sessionid (sessionid), + INDEX idx_eventtime (eventtime), + INDEX idx_toolnumber (toolnumber), + INDEX idx_oot (oot), + CONSTRAINT fk_udctooldata_partrun FOREIGN KEY (partrunid) REFERENCES udcparts(partrunid) ON DELETE SET NULL, + CONSTRAINT fk_udctooldata_session FOREIGN KEY (sessionid) REFERENCES udcsessions(sessionid) ON DELETE CASCADE +) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4; + +-- Errors table - error events from UDC logs +CREATE TABLE IF NOT EXISTS udcerrors ( + errorid INT AUTO_INCREMENT PRIMARY KEY, + sessionid INT, + machinenumber VARCHAR(20), + eventtime DATETIME, + errortype VARCHAR(100), + errormessage TEXT, + sourcemethod VARCHAR(255), + INDEX idx_sessionid (sessionid), + INDEX idx_machinenumber (machinenumber), + INDEX idx_eventtime (eventtime), + INDEX idx_errortype (errortype) +) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4; + +-- Connections table - serial/network connection events +CREATE TABLE IF NOT EXISTS udcconnections ( + connectionid INT AUTO_INCREMENT PRIMARY KEY, + sessionid INT, + machinenumber VARCHAR(20), + eventtime DATETIME, + eventtype VARCHAR(20), + comport VARCHAR(20), + details VARCHAR(255), + INDEX idx_sessionid (sessionid), + INDEX idx_machinenumber (machinenumber), + INDEX idx_eventtime (eventtime), + INDEX idx_eventtype (eventtype) +) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4; + +-- Active sessions table - tracks currently running machines +CREATE TABLE IF NOT EXISTS udcactivesessions ( + activeid INT AUTO_INCREMENT PRIMARY KEY, + machinenumber VARCHAR(20) NOT NULL, + sessionid INT, + partnumber VARCHAR(50), + badgenumber VARCHAR(20), + partsrun INT DEFAULT 0, + sessionstart DATETIME, + lastupdate DATETIME, + UNIQUE INDEX idx_machinenumber (machinenumber), + INDEX idx_sessionid (sessionid), + INDEX idx_lastupdate (lastupdate) +) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4; + +-- Header updates table - badge changes during part runs +CREATE TABLE IF NOT EXISTS udcheaderupdates ( + updateid INT AUTO_INCREMENT PRIMARY KEY, + partrunid INT, + sessionid INT, + machinenumber VARCHAR(20), + eventtime DATETIME, + details VARCHAR(255), + description VARCHAR(255), + badgenumber VARCHAR(20), + INDEX idx_partrunid (partrunid), + INDEX idx_sessionid (sessionid), + INDEX idx_machinenumber (machinenumber), + INDEX idx_eventtime (eventtime) +) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4; + +-- Violations table - item crossing value changes +CREATE TABLE IF NOT EXISTS udcviolations ( + violationid INT AUTO_INCREMENT PRIMARY KEY, + partrunid INT, + sessionid INT, + machinenumber VARCHAR(20), + eventtime DATETIME, + previousval DECIMAL(12,4), + currentval DECIMAL(12,4), + badgenumber VARCHAR(20), + itemno VARCHAR(20), + crossingdesc VARCHAR(255), + INDEX idx_partrunid (partrunid), + INDEX idx_sessionid (sessionid), + INDEX idx_machinenumber (machinenumber), + INDEX idx_eventtime (eventtime) +) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4; + +-- ============================================================================ +-- Useful Views for Reporting +-- ============================================================================ + +-- Part runs with machine info +CREATE OR REPLACE VIEW vwudcpartruns AS +SELECT + p.partrunid, + p.sessionid, + p.machineid, + s.machinenumber, + p.partnumber, + p.opernumber, + p.serialnumber, + p.programname, + p.jobnumber, + p.badgenumber, + p.programstart, + p.programend, + p.cycletime, + p.changeover, + p.measurementcount, + p.manualcount, + p.probecount, + p.ootcount +FROM udcparts p +JOIN udcsessions s ON p.sessionid = s.sessionid; + +-- Operator stats aggregation +CREATE OR REPLACE VIEW vwudcoperatorstats AS +SELECT + badgenumber, + COUNT(*) AS partsrun, + AVG(cycletime) AS avgcycletime, + AVG(changeover) AS avgchangeover, + SUM(measurementcount) AS totalmeasurements, + SUM(manualcount) AS totalmanual, + SUM(ootcount) AS totaloot, + MIN(programstart) AS firstrun, + MAX(programend) AS lastrun +FROM udcparts +WHERE badgenumber IS NOT NULL AND badgenumber != '' +GROUP BY badgenumber; + +-- Machine stats aggregation +CREATE OR REPLACE VIEW vwudcmachinestats AS +SELECT + s.machinenumber, + p.machineid, + COUNT(*) AS partsrun, + AVG(p.cycletime) AS avgcycletime, + AVG(p.changeover) AS avgchangeover, + SUM(p.measurementcount) AS totalmeasurements, + SUM(p.ootcount) AS totaloot, + MIN(p.programstart) AS firstrun, + MAX(p.programend) AS lastrun +FROM udcparts p +JOIN udcsessions s ON p.sessionid = s.sessionid +GROUP BY s.machinenumber, p.machineid; + +-- Manual request response times +CREATE OR REPLACE VIEW vwudcmanualtiming AS +SELECT + r.requestid, + p.badgenumber, + s.machinenumber, + r.requesttime, + r.responsetime, + r.responseseconds, + r.description +FROM udcmanualrequests r +JOIN udcparts p ON r.partrunid = p.partrunid +JOIN udcsessions s ON p.sessionid = s.sessionid; + +-- ============================================================================ +-- Verify +-- ============================================================================ +SELECT 'UDC tables created successfully' AS status; +SHOW TABLES LIKE 'udc%';