Add UDC Performance Dashboard and Tool Health features
- 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 <noreply@anthropic.com>
This commit is contained in:
292
sql/udctables.sql
Normal file
292
sql/udctables.sql
Normal file
@@ -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%';
|
||||
Reference in New Issue
Block a user