Fix network device description/machinenotes display and edit
- Fix ADO cursor issue where reading rs("description") twice caused
empty values (IsNull check consumed the field value)
- Change all device pages to read description field once using
`description = rs("description") & ""` pattern
- Add deviceDescription variable in displaydevice.asp
- Fix machinetypeid mapping: IDF=17, Camera=18 (was swapped)
- Add model dropdown fix to include currently assigned model
- Add server application tracking feature
- Various other improvements and fixes
Files affected:
- displaydevice.asp, displaylocationdevice.asp
- deviceaccesspoint.asp, deviceserver.asp, deviceswitch.asp
- devicecamera.asp, deviceidf.asp
- savenetworkdevice.asp, networkdevices.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,39 +0,0 @@
|
||||
-- ============================================================================
|
||||
-- eDNC Special Character Fix - Database Setup
|
||||
-- Run on PRODUCTION to create ednclogs table
|
||||
-- Created: 2025-12-12
|
||||
-- ============================================================================
|
||||
|
||||
-- Create ednclogs table (uses machineid FK to machines table)
|
||||
CREATE TABLE IF NOT EXISTS ednclogs (
|
||||
logid INT AUTO_INCREMENT PRIMARY KEY,
|
||||
machineid INT NOT NULL,
|
||||
filename VARCHAR(255) NOT NULL,
|
||||
action ENUM('cleaned', 'ok', 'failed', 'error', 'started', 'stopped') NOT NULL,
|
||||
bytes_removed INT DEFAULT 0,
|
||||
version VARCHAR(20),
|
||||
message VARCHAR(500),
|
||||
created DATETIME DEFAULT CURRENT_TIMESTAMP,
|
||||
INDEX idx_machineid (machineid),
|
||||
INDEX idx_created (created),
|
||||
INDEX idx_action (action)
|
||||
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4;
|
||||
|
||||
-- View for easy querying (includes hostname from machines)
|
||||
CREATE OR REPLACE VIEW vw_ednclogs AS
|
||||
SELECT
|
||||
l.logid,
|
||||
l.machineid,
|
||||
m.hostname,
|
||||
l.filename,
|
||||
l.action,
|
||||
l.bytes_removed,
|
||||
l.version,
|
||||
l.message,
|
||||
l.created
|
||||
FROM ednclogs l
|
||||
INNER JOIN machines m ON l.machineid = m.machineid;
|
||||
|
||||
-- Verify
|
||||
DESCRIBE ednclogs;
|
||||
SELECT 'View created: vw_ednclogs' AS status;
|
||||
@@ -53,6 +53,82 @@ CREATE TABLE IF NOT EXISTS udctooldata_daily (
|
||||
INDEX idx_toolnumber (toolnumber)
|
||||
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4;
|
||||
|
||||
-- Daily parts/production summary (aggregated from udcparts)
|
||||
CREATE TABLE IF NOT EXISTS udcpartsdaily (
|
||||
summaryid INT AUTO_INCREMENT PRIMARY KEY,
|
||||
summarydate DATE NOT NULL,
|
||||
machinenumber VARCHAR(20) NOT NULL,
|
||||
badgenumber VARCHAR(50),
|
||||
partscount INT DEFAULT 0,
|
||||
ootparts INT DEFAULT 0,
|
||||
totalmeasurements INT DEFAULT 0,
|
||||
totaloot INT DEFAULT 0,
|
||||
avgcycletime DECIMAL(10,2),
|
||||
mincycletime DECIMAL(10,2),
|
||||
maxcycletime DECIMAL(10,2),
|
||||
avgchangeover DECIMAL(10,2),
|
||||
dateadded DATETIME DEFAULT CURRENT_TIMESTAMP,
|
||||
UNIQUE INDEX uk_daily_machine_badge (summarydate, machinenumber, badgenumber),
|
||||
INDEX idx_summarydate (summarydate),
|
||||
INDEX idx_machinenumber (machinenumber),
|
||||
INDEX idx_badgenumber (badgenumber)
|
||||
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4;
|
||||
|
||||
-- Daily manual request summary (aggregated from udcmanualrequests)
|
||||
CREATE TABLE IF NOT EXISTS udcmanualrequestsdaily (
|
||||
summaryid INT AUTO_INCREMENT PRIMARY KEY,
|
||||
summarydate DATE NOT NULL,
|
||||
machinenumber VARCHAR(20) NOT NULL,
|
||||
requestcount INT DEFAULT 0,
|
||||
avgresponseseconds DECIMAL(10,2),
|
||||
minresponseseconds DECIMAL(10,2),
|
||||
maxresponseseconds DECIMAL(10,2),
|
||||
dateadded DATETIME DEFAULT CURRENT_TIMESTAMP,
|
||||
UNIQUE INDEX uk_daily_machine_manual (summarydate, machinenumber),
|
||||
INDEX idx_summarydate (summarydate),
|
||||
INDEX idx_machinenumber (machinenumber)
|
||||
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4;
|
||||
|
||||
-- Daily error summary (aggregated from udcerrors)
|
||||
CREATE TABLE IF NOT EXISTS udcerrorsdaily (
|
||||
summaryid INT AUTO_INCREMENT PRIMARY KEY,
|
||||
summarydate DATE NOT NULL,
|
||||
machinenumber VARCHAR(20) NOT NULL,
|
||||
errortype VARCHAR(50),
|
||||
errorcount INT DEFAULT 0,
|
||||
dateadded DATETIME DEFAULT CURRENT_TIMESTAMP,
|
||||
UNIQUE INDEX uk_daily_machine_error (summarydate, machinenumber, errortype),
|
||||
INDEX idx_summarydate (summarydate),
|
||||
INDEX idx_machinenumber (machinenumber)
|
||||
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4;
|
||||
|
||||
-- Daily violation summary (aggregated from udcviolations - CLM specific)
|
||||
CREATE TABLE IF NOT EXISTS udcviolationsdaily (
|
||||
summaryid INT AUTO_INCREMENT PRIMARY KEY,
|
||||
summarydate DATE NOT NULL,
|
||||
machinenumber VARCHAR(20) NOT NULL,
|
||||
badgenumber VARCHAR(20),
|
||||
violationcount INT DEFAULT 0,
|
||||
dateadded DATETIME DEFAULT CURRENT_TIMESTAMP,
|
||||
UNIQUE INDEX uk_daily_machine_badge_viol (summarydate, machinenumber, badgenumber),
|
||||
INDEX idx_summarydate (summarydate),
|
||||
INDEX idx_machinenumber (machinenumber),
|
||||
INDEX idx_badgenumber (badgenumber)
|
||||
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4;
|
||||
|
||||
-- Daily header updates summary (aggregated from udcheaderupdates - badge changes)
|
||||
CREATE TABLE IF NOT EXISTS udcheaderupdatesdaily (
|
||||
summaryid INT AUTO_INCREMENT PRIMARY KEY,
|
||||
summarydate DATE NOT NULL,
|
||||
machinenumber VARCHAR(20) NOT NULL,
|
||||
updatecount INT DEFAULT 0,
|
||||
uniqueoperators INT DEFAULT 0,
|
||||
dateadded DATETIME DEFAULT CURRENT_TIMESTAMP,
|
||||
UNIQUE INDEX uk_daily_machine_header (summarydate, machinenumber),
|
||||
INDEX idx_summarydate (summarydate),
|
||||
INDEX idx_machinenumber (machinenumber)
|
||||
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4;
|
||||
|
||||
-- ============================================================================
|
||||
-- Stored Procedure: Summarize a specific date's data
|
||||
-- ============================================================================
|
||||
@@ -126,6 +202,106 @@ BEGIN
|
||||
avg_deviation = VALUES(avg_deviation),
|
||||
max_deviation = VALUES(max_deviation),
|
||||
dateadded = CURRENT_TIMESTAMP;
|
||||
|
||||
-- Summarize parts/production for the date
|
||||
INSERT INTO udcpartsdaily
|
||||
(summarydate, machinenumber, badgenumber, partscount, ootparts, totalmeasurements, totaloot,
|
||||
avgcycletime, mincycletime, maxcycletime, avgchangeover)
|
||||
SELECT
|
||||
DATE(p.programstart) as summarydate,
|
||||
s.machinenumber,
|
||||
COALESCE(p.badgenumber, 'UNKNOWN') as badgenumber,
|
||||
COUNT(*) as partscount,
|
||||
SUM(CASE WHEN p.ootcount > 0 THEN 1 ELSE 0 END) as ootparts,
|
||||
SUM(COALESCE(p.measurementcount, 0)) as totalmeasurements,
|
||||
SUM(COALESCE(p.ootcount, 0)) as totaloot,
|
||||
ROUND(AVG(p.cycletime), 2) as avgcycletime,
|
||||
ROUND(MIN(p.cycletime), 2) as mincycletime,
|
||||
ROUND(MAX(p.cycletime), 2) as maxcycletime,
|
||||
ROUND(AVG(p.changeover), 2) as avgchangeover
|
||||
FROM udcparts p
|
||||
JOIN udcsessions s ON p.sessionid = s.sessionid
|
||||
WHERE DATE(p.programstart) = p_date
|
||||
GROUP BY DATE(p.programstart), s.machinenumber, COALESCE(p.badgenumber, 'UNKNOWN')
|
||||
ON DUPLICATE KEY UPDATE
|
||||
partscount = VALUES(partscount),
|
||||
ootparts = VALUES(ootparts),
|
||||
totalmeasurements = VALUES(totalmeasurements),
|
||||
totaloot = VALUES(totaloot),
|
||||
avgcycletime = VALUES(avgcycletime),
|
||||
mincycletime = VALUES(mincycletime),
|
||||
maxcycletime = VALUES(maxcycletime),
|
||||
avgchangeover = VALUES(avgchangeover),
|
||||
dateadded = CURRENT_TIMESTAMP;
|
||||
|
||||
-- Summarize manual requests for the date
|
||||
INSERT INTO udcmanualrequestsdaily
|
||||
(summarydate, machinenumber, requestcount, avgresponseseconds, minresponseseconds, maxresponseseconds)
|
||||
SELECT
|
||||
DATE(mr.requesttime) as summarydate,
|
||||
s.machinenumber,
|
||||
COUNT(*) as requestcount,
|
||||
ROUND(AVG(mr.responseseconds), 2) as avgresponseseconds,
|
||||
ROUND(MIN(mr.responseseconds), 2) as minresponseseconds,
|
||||
ROUND(MAX(mr.responseseconds), 2) as maxresponseseconds
|
||||
FROM udcmanualrequests mr
|
||||
JOIN udcparts p ON mr.partrunid = p.partrunid
|
||||
JOIN udcsessions s ON p.sessionid = s.sessionid
|
||||
WHERE DATE(mr.requesttime) = p_date
|
||||
GROUP BY DATE(mr.requesttime), s.machinenumber
|
||||
ON DUPLICATE KEY UPDATE
|
||||
requestcount = VALUES(requestcount),
|
||||
avgresponseseconds = VALUES(avgresponseseconds),
|
||||
minresponseseconds = VALUES(minresponseseconds),
|
||||
maxresponseseconds = VALUES(maxresponseseconds),
|
||||
dateadded = CURRENT_TIMESTAMP;
|
||||
|
||||
-- Summarize errors for the date
|
||||
INSERT INTO udcerrorsdaily
|
||||
(summarydate, machinenumber, errortype, errorcount)
|
||||
SELECT
|
||||
DATE(e.eventtime) as summarydate,
|
||||
COALESCE(e.machinenumber, s.machinenumber) as machinenumber,
|
||||
e.errortype,
|
||||
COUNT(*) as errorcount
|
||||
FROM udcerrors e
|
||||
LEFT JOIN udcsessions s ON e.sessionid = s.sessionid
|
||||
WHERE DATE(e.eventtime) = p_date
|
||||
GROUP BY DATE(e.eventtime), COALESCE(e.machinenumber, s.machinenumber), e.errortype
|
||||
ON DUPLICATE KEY UPDATE
|
||||
errorcount = VALUES(errorcount),
|
||||
dateadded = CURRENT_TIMESTAMP;
|
||||
|
||||
-- Summarize violations for the date (CLM specific)
|
||||
INSERT INTO udcviolationsdaily
|
||||
(summarydate, machinenumber, badgenumber, violationcount)
|
||||
SELECT
|
||||
DATE(v.eventtime) as summarydate,
|
||||
v.machinenumber,
|
||||
COALESCE(v.badgenumber, 'UNKNOWN') as badgenumber,
|
||||
COUNT(*) as violationcount
|
||||
FROM udcviolations v
|
||||
WHERE DATE(v.eventtime) = p_date
|
||||
GROUP BY DATE(v.eventtime), v.machinenumber, COALESCE(v.badgenumber, 'UNKNOWN')
|
||||
ON DUPLICATE KEY UPDATE
|
||||
violationcount = VALUES(violationcount),
|
||||
dateadded = CURRENT_TIMESTAMP;
|
||||
|
||||
-- Summarize header updates for the date (badge changes)
|
||||
INSERT INTO udcheaderupdatesdaily
|
||||
(summarydate, machinenumber, updatecount, uniqueoperators)
|
||||
SELECT
|
||||
DATE(h.eventtime) as summarydate,
|
||||
h.machinenumber,
|
||||
COUNT(*) as updatecount,
|
||||
COUNT(DISTINCT h.badgenumber) as uniqueoperators
|
||||
FROM udcheaderupdates h
|
||||
WHERE DATE(h.eventtime) = p_date
|
||||
GROUP BY DATE(h.eventtime), h.machinenumber
|
||||
ON DUPLICATE KEY UPDATE
|
||||
updatecount = VALUES(updatecount),
|
||||
uniqueoperators = VALUES(uniqueoperators),
|
||||
dateadded = CURRENT_TIMESTAMP;
|
||||
END //
|
||||
|
||||
DELIMITER ;
|
||||
@@ -300,6 +476,138 @@ SELECT
|
||||
FROM udctooldata_daily
|
||||
GROUP BY DATE_FORMAT(summarydate, '%Y-%m'), machinenumber, toolnumber;
|
||||
|
||||
-- Weekly parts/production trends from daily summaries
|
||||
CREATE OR REPLACE VIEW vwudcparts_weekly AS
|
||||
SELECT
|
||||
YEARWEEK(summarydate, 1) as yearweek,
|
||||
MIN(summarydate) as week_start,
|
||||
machinenumber,
|
||||
SUM(partscount) as partscount,
|
||||
SUM(ootparts) as ootparts,
|
||||
SUM(totalmeasurements) as totalmeasurements,
|
||||
SUM(totaloot) as totaloot,
|
||||
ROUND(AVG(avgcycletime), 2) as avgcycletime,
|
||||
ROUND(AVG(avgchangeover), 2) as avgchangeover
|
||||
FROM udcpartsdaily
|
||||
GROUP BY YEARWEEK(summarydate, 1), machinenumber;
|
||||
|
||||
-- Monthly parts/production trends from daily summaries
|
||||
CREATE OR REPLACE VIEW vwudcparts_monthly AS
|
||||
SELECT
|
||||
DATE_FORMAT(summarydate, '%Y-%m') as yearmonth,
|
||||
machinenumber,
|
||||
SUM(partscount) as partscount,
|
||||
SUM(ootparts) as ootparts,
|
||||
SUM(totalmeasurements) as totalmeasurements,
|
||||
SUM(totaloot) as totaloot,
|
||||
ROUND(AVG(avgcycletime), 2) as avgcycletime,
|
||||
ROUND(AVG(avgchangeover), 2) as avgchangeover
|
||||
FROM udcpartsdaily
|
||||
GROUP BY DATE_FORMAT(summarydate, '%Y-%m'), machinenumber;
|
||||
|
||||
-- Weekly manual request trends from daily summaries
|
||||
CREATE OR REPLACE VIEW vwudcmanualrequests_weekly AS
|
||||
SELECT
|
||||
YEARWEEK(summarydate, 1) as yearweek,
|
||||
MIN(summarydate) as week_start,
|
||||
machinenumber,
|
||||
SUM(requestcount) as requestcount,
|
||||
ROUND(AVG(avgresponseseconds), 2) as avgresponseseconds
|
||||
FROM udcmanualrequestsdaily
|
||||
GROUP BY YEARWEEK(summarydate, 1), machinenumber;
|
||||
|
||||
-- Monthly manual request trends from daily summaries
|
||||
CREATE OR REPLACE VIEW vwudcmanualrequests_monthly AS
|
||||
SELECT
|
||||
DATE_FORMAT(summarydate, '%Y-%m') as yearmonth,
|
||||
machinenumber,
|
||||
SUM(requestcount) as requestcount,
|
||||
ROUND(AVG(avgresponseseconds), 2) as avgresponseseconds
|
||||
FROM udcmanualrequestsdaily
|
||||
GROUP BY DATE_FORMAT(summarydate, '%Y-%m'), machinenumber;
|
||||
|
||||
-- Weekly error trends from daily summaries
|
||||
CREATE OR REPLACE VIEW vwudcerrors_weekly AS
|
||||
SELECT
|
||||
YEARWEEK(summarydate, 1) as yearweek,
|
||||
MIN(summarydate) as week_start,
|
||||
machinenumber,
|
||||
errortype,
|
||||
SUM(errorcount) as errorcount
|
||||
FROM udcerrorsdaily
|
||||
GROUP BY YEARWEEK(summarydate, 1), machinenumber, errortype;
|
||||
|
||||
-- Monthly error trends from daily summaries
|
||||
CREATE OR REPLACE VIEW vwudcerrors_monthly AS
|
||||
SELECT
|
||||
DATE_FORMAT(summarydate, '%Y-%m') as yearmonth,
|
||||
machinenumber,
|
||||
errortype,
|
||||
SUM(errorcount) as errorcount
|
||||
FROM udcerrorsdaily
|
||||
GROUP BY DATE_FORMAT(summarydate, '%Y-%m'), machinenumber, errortype;
|
||||
|
||||
-- Weekly violation trends from daily summaries (CLM specific)
|
||||
CREATE OR REPLACE VIEW vwudcviolations_weekly AS
|
||||
SELECT
|
||||
YEARWEEK(summarydate, 1) as yearweek,
|
||||
MIN(summarydate) as week_start,
|
||||
machinenumber,
|
||||
SUM(violationcount) as violationcount
|
||||
FROM udcviolationsdaily
|
||||
GROUP BY YEARWEEK(summarydate, 1), machinenumber;
|
||||
|
||||
-- Monthly violation trends from daily summaries (CLM specific)
|
||||
CREATE OR REPLACE VIEW vwudcviolations_monthly AS
|
||||
SELECT
|
||||
DATE_FORMAT(summarydate, '%Y-%m') as yearmonth,
|
||||
machinenumber,
|
||||
SUM(violationcount) as violationcount
|
||||
FROM udcviolationsdaily
|
||||
GROUP BY DATE_FORMAT(summarydate, '%Y-%m'), machinenumber;
|
||||
|
||||
-- Violations by operator (monthly)
|
||||
CREATE OR REPLACE VIEW vwudcviolations_byoperator AS
|
||||
SELECT
|
||||
DATE_FORMAT(summarydate, '%Y-%m') as yearmonth,
|
||||
machinenumber,
|
||||
badgenumber,
|
||||
SUM(violationcount) as violationcount
|
||||
FROM udcviolationsdaily
|
||||
GROUP BY DATE_FORMAT(summarydate, '%Y-%m'), machinenumber, badgenumber;
|
||||
|
||||
-- Weekly header update trends from daily summaries (badge changes)
|
||||
CREATE OR REPLACE VIEW vwudcheaderupdates_weekly AS
|
||||
SELECT
|
||||
YEARWEEK(summarydate, 1) as yearweek,
|
||||
MIN(summarydate) as week_start,
|
||||
machinenumber,
|
||||
SUM(updatecount) as updatecount,
|
||||
AVG(uniqueoperators) as avgoperators
|
||||
FROM udcheaderupdatesdaily
|
||||
GROUP BY YEARWEEK(summarydate, 1), machinenumber;
|
||||
|
||||
-- Monthly header update trends from daily summaries (badge changes)
|
||||
CREATE OR REPLACE VIEW vwudcheaderupdates_monthly AS
|
||||
SELECT
|
||||
DATE_FORMAT(summarydate, '%Y-%m') as yearmonth,
|
||||
machinenumber,
|
||||
SUM(updatecount) as updatecount,
|
||||
AVG(uniqueoperators) as avgoperators
|
||||
FROM udcheaderupdatesdaily
|
||||
GROUP BY DATE_FORMAT(summarydate, '%Y-%m'), machinenumber;
|
||||
|
||||
-- Monthly changeover time trends (from parts daily)
|
||||
CREATE OR REPLACE VIEW vwudcchangeover_monthly AS
|
||||
SELECT
|
||||
DATE_FORMAT(summarydate, '%Y-%m') as yearmonth,
|
||||
machinenumber,
|
||||
ROUND(AVG(avgchangeover), 0) as avgchangeover,
|
||||
SUM(partscount) as partscount
|
||||
FROM udcpartsdaily
|
||||
WHERE avgchangeover IS NOT NULL AND avgchangeover > 0
|
||||
GROUP BY DATE_FORMAT(summarydate, '%Y-%m'), machinenumber;
|
||||
|
||||
-- ============================================================================
|
||||
-- Usage Instructions
|
||||
-- ============================================================================
|
||||
|
||||
Reference in New Issue
Block a user