diff --git a/sql/udctables.sql b/sql/udctables.sql index 2401906..361bdb5 100644 --- a/sql/udctables.sql +++ b/sql/udctables.sql @@ -164,16 +164,14 @@ CREATE TABLE IF NOT EXISTS udcconnections ( -- 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, + machinenumber VARCHAR(20) NOT NULL PRIMARY KEY, + filepath VARCHAR(255), partnumber VARCHAR(50), badgenumber VARCHAR(20), partsrun INT DEFAULT 0, - sessionstart DATETIME, lastupdate DATETIME, - UNIQUE INDEX idx_machinenumber (machinenumber), - INDEX idx_sessionid (sessionid), + sessionstart DATETIME, + lastseen DATETIME DEFAULT CURRENT_TIMESTAMP, INDEX idx_lastupdate (lastupdate) ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4; @@ -302,6 +300,178 @@ FROM udcmanualrequests r JOIN udcparts p ON r.partrunid = p.partrunid JOIN udcsessions s ON p.sessionid = s.sessionid; +-- Tool health stats by machine +CREATE OR REPLACE VIEW vwudctoolhealthbymachine AS +SELECT + s.machinenumber, + COUNT(DISTINCT t.toolnumber) AS unique_tools, + COUNT(*) AS total_measurements, + SUM(t.oot) AS oot_count, + ROUND(AVG(t.deviation), 6) AS avg_deviation, + ROUND(MAX(ABS(t.deviation)), 6) AS max_deviation, + MIN(t.eventtime) AS first_measurement, + MAX(t.eventtime) AS last_measurement +FROM udctooldata t +JOIN udcsessions s ON t.sessionid = s.sessionid +GROUP BY s.machinenumber; + +-- Tool health stats by tool number (across all machines) +CREATE OR REPLACE VIEW vwudctoolhealthbytool AS +SELECT + s.machinenumber, + t.toolnumber, + t.description, + COUNT(*) AS measurements, + SUM(t.oot) AS oot_count, + ROUND(AVG(t.deviation), 6) AS avg_deviation, + ROUND(MAX(ABS(t.deviation)), 6) AS max_deviation, + MAX(t.eventtime) AS last_measured +FROM udctooldata t +JOIN udcsessions s ON t.sessionid = s.sessionid +GROUP BY s.machinenumber, t.toolnumber, t.description; + +-- Out of tolerance measurements detail +CREATE OR REPLACE VIEW vwudcootdetail AS +SELECT + m.measurementid, + s.machinenumber, + p.partnumber, + p.serialnumber, + p.badgenumber, + m.eventtime, + m.method, + m.dimid, + m.description, + m.minval, + m.maxval, + m.actualval, + m.deviation +FROM udcmeasurements m +JOIN udcsessions s ON m.sessionid = s.sessionid +LEFT JOIN udcparts p ON m.partrunid = p.partrunid +WHERE m.oot = 1; + +-- Tool OOT detail +CREATE OR REPLACE VIEW vwudctoolootdetail AS +SELECT + t.tooldataid, + s.machinenumber, + p.partnumber, + p.badgenumber, + t.eventtime, + t.toolnumber, + t.description, + t.minval, + t.maxval, + t.actualval, + t.deviation +FROM udctooldata t +JOIN udcsessions s ON t.sessionid = s.sessionid +LEFT JOIN udcparts p ON t.partrunid = p.partrunid +WHERE t.oot = 1; + +-- Active sessions with machine details +CREATE OR REPLACE VIEW vwudcactivesessions AS +SELECT + a.machinenumber, + m.hostname, + m.alias, + bu.businessunit, + a.partnumber, + a.badgenumber, + a.partsrun, + a.sessionstart, + a.lastupdate, + a.lastseen, + TIMESTAMPDIFF(MINUTE, a.sessionstart, NOW()) AS runtime_minutes +FROM udcactivesessions a +LEFT JOIN machines m ON m.machinenumber = a.machinenumber +LEFT JOIN businessunits bu ON m.businessunitid = bu.businessunitid; + +-- Violations with context +CREATE OR REPLACE VIEW vwudcviolations AS +SELECT + v.violationid, + v.machinenumber, + v.eventtime, + v.badgenumber, + v.itemno, + v.crossingdesc, + v.previousval, + v.currentval, + p.partnumber, + p.serialnumber +FROM udcviolations v +LEFT JOIN udcparts p ON v.partrunid = p.partrunid; + +-- Daily production summary +CREATE OR REPLACE VIEW vwudcdailyproduction AS +SELECT + DATE(p.programstart) AS production_date, + s.machinenumber, + COUNT(*) AS parts_produced, + SUM(p.ootcount) AS total_oot, + ROUND(SUM(p.ootcount) * 100.0 / COUNT(*), 2) AS oot_rate, + ROUND(AVG(p.cycletime) / 60, 1) AS avg_cycle_minutes, + ROUND(AVG(p.changeover) / 60, 1) AS avg_changeover_minutes, + ROUND(SUM(p.cycletime) / 3600, 1) AS total_runtime_hours, + COUNT(DISTINCT p.badgenumber) AS unique_operators +FROM udcparts p +JOIN udcsessions s ON p.sessionid = s.sessionid +WHERE p.programstart IS NOT NULL +GROUP BY DATE(p.programstart), s.machinenumber; + +-- Error summary by machine +CREATE OR REPLACE VIEW vwudcerrorsummary AS +SELECT + e.machinenumber, + e.errortype, + COUNT(*) AS error_count, + MIN(e.eventtime) AS first_occurrence, + MAX(e.eventtime) AS last_occurrence +FROM udcerrors e +GROUP BY e.machinenumber, e.errortype; + +-- Connection events summary +CREATE OR REPLACE VIEW vwudcconnectionsummary AS +SELECT + c.machinenumber, + c.eventtype, + c.comport, + COUNT(*) AS event_count, + MAX(c.eventtime) AS last_event +FROM udcconnections c +GROUP BY c.machinenumber, c.eventtype, c.comport; + +-- Header updates (badge changes) with context +CREATE OR REPLACE VIEW vwudcheaderupdates AS +SELECT + h.updateid, + h.machinenumber, + h.eventtime, + h.badgenumber, + h.description, + h.details, + p.partnumber, + p.serialnumber +FROM udcheaderupdates h +LEFT JOIN udcparts p ON h.partrunid = p.partrunid; + +-- CLM file import status +CREATE OR REPLACE VIEW vwudcclmfiles AS +SELECT + f.fileid, + f.machinenumber, + f.filename, + f.filehash, + f.filemodtime, + f.recordcount, + f.importdate, + p.partnumber, + p.serialnumber +FROM udcclmfiles f +LEFT JOIN udcparts p ON f.partrunid = p.partrunid; + -- ============================================================================ -- Verify -- ============================================================================