Updated Parent project + Scripts

This commit is contained in:
gigi.mamaladze 2025-10-11 21:05:45 +04:00
parent bdac7123e3
commit 98268ffc8d
11 changed files with 206 additions and 178 deletions

View File

@ -6,9 +6,9 @@
"$": [
"ts",
192,
1759919476692
1760193648107
],
"$ts": 1759919476691
"$ts": 1760193648057
}
}
},

View File

@ -641,7 +641,7 @@
"component": {
"onActionPerformed": {
"config": {
"script": "\tsystem.perspective.navigate(\"/Windows/Statistics\")\n\tquery2 \u003d \"\"\"\n\tCREATE TABLE IF NOT EXISTS dumper_cycles (\n\t id INT AUTO_INCREMENT PRIMARY KEY,\n\t t_stamp DATETIME NOT NULL,\n\t ulgl1 TINYINT(1) DEFAULT 0,\n\t ulgl2 TINYINT(1) DEFAULT 0,\n\t ulgl3 TINYINT(1) DEFAULT 0,\n\t ulgl4 TINYINT(1) DEFAULT 0\n\t);\n\t\"\"\"\n\tsystem.db.runUpdateQuery(query2, \"MariaDB\")\n\t"
"script": "\tsystem.perspective.navigate(\"/Windows/Statistics\")"
},
"scope": "G",
"type": "script"

View File

@ -1,28 +1,37 @@
-- GetActiveAlarms: Returns all currently active (uncleared) alarms
-- Uses: idx_alarm_events_active, idx_alarm_events_clear, idx_alarm_event_data_lookup
-- Expected performance: <200ms on 37K rows, <500ms on 1M+ rows
-- Param: :priorityList (comma-separated priority numbers, or empty string for all)
SELECT
ae.id AS ID,
ae.eventtime AS StartTimestamp,
CONCAT(
LPAD(FLOOR(TIMESTAMPDIFF(SECOND, ae.eventtime, NOW())/3600), 2, '0'), ':',
LPAD(FLOOR((TIMESTAMPDIFF(SECOND, ae.eventtime, NOW())%3600)/60), 2, '0'), ':',
LPAD( (TIMESTAMPDIFF(SECOND, ae.eventtime, NOW())%60), 2, '0')
) AS Duration,
CONCAT(REPLACE(ae.displaypath,'_','-'),' ', SUBSTRING_INDEX(ae.source,':/alm:',-1)) AS Description,
TIME_FORMAT(SEC_TO_TIME(TIMESTAMPDIFF(SECOND, ae.eventtime, NOW())), '%H:%i:%s') AS Duration,
CONCAT(REPLACE(ae.displaypath, '_', '-'), ' ', SUBSTRING_INDEX(ae.source, ':/alm:', -1)) AS Description,
CASE ae.priority
WHEN 0 THEN 'Diagnostic' WHEN 1 THEN 'Low' WHEN 2 THEN 'Medium'
WHEN 3 THEN 'High' WHEN 4 THEN 'Critical' ELSE 'Unknown'
WHEN 0 THEN 'Diagnostic'
WHEN 1 THEN 'Low'
WHEN 2 THEN 'Medium'
WHEN 3 THEN 'High'
WHEN 4 THEN 'Critical'
ELSE 'Unknown'
END AS Priority,
CONCAT(ae.displaypath,'.HMI.Alarm.', SUBSTRING_INDEX(aed.strValue,'/',-1)) AS Tag,
SUBSTRING_INDEX(SUBSTRING_INDEX(aed.strValue,'/',2),'/',-1) AS Location,
CONCAT(ae.displaypath, '.HMI.Alarm.', SUBSTRING_INDEX(IFNULL(aed.strValue, ''), '/', -1)) AS Tag,
SUBSTRING_INDEX(SUBSTRING_INDEX(IFNULL(aed.strValue, ''), '/', 2), '/', -1) AS Location,
aed.strValue AS FullTag,
ae.displaypath AS Device
FROM alarm_events ae
LEFT JOIN alarm_events clr
ON clr.eventid = ae.eventid AND clr.eventtype = 1
LEFT JOIN alarm_event_data aed
FROM alarm_events ae FORCE INDEX (idx_alarm_events_active)
LEFT JOIN alarm_event_data aed FORCE INDEX (idx_alarm_event_data_lookup)
ON aed.id = ae.id AND aed.propname = 'myTag'
WHERE ae.eventtype = 0
AND clr.eventid IS NULL
AND ae.displaypath NOT LIKE '%System Startup%'
AND ae.source NOT LIKE '%System Startup%'
AND ae.source NOT LIKE '%System Startup%'
AND (:priorityList = '' OR FIND_IN_SET(CAST(ae.priority AS CHAR), :priorityList) > 0)
ORDER BY ae.eventtime DESC;
-- FORCE INDEX ensures idx_alarm_events_clear is used in subquery
AND NOT EXISTS (
SELECT 1
FROM alarm_events clr FORCE INDEX (idx_alarm_events_clear)
WHERE clr.eventid = ae.eventid
AND clr.eventtype = 1
)
ORDER BY ae.eventtime DESC;

View File

@ -1,6 +1,10 @@
-- GetActiveAlarmsByLocationAndPriority: Count active alarms grouped by location and priority
-- Uses: idx_alarm_events_active, idx_alarm_events_clear, idx_alarm_event_data_lookup, idx_alarm_events_priority
-- Expected performance: <100ms on 37K rows, <200ms on 1M+ rows
SELECT
SUBSTRING_INDEX(SUBSTRING_INDEX(strValue, '/', 2), '/', -1) AS Location,
CASE priority
SUBSTRING_INDEX(SUBSTRING_INDEX(IFNULL(aed.strValue, ''), '/', 2), '/', -1) AS Location,
CASE ae.priority
WHEN 0 THEN 'Diagnostic'
WHEN 1 THEN 'Low'
WHEN 2 THEN 'Medium'
@ -9,25 +13,18 @@ SELECT
ELSE 'Unknown'
END AS Priority,
COUNT(*) AS Count
FROM (
SELECT
ae.id,
ae.eventid,
ae.priority,
aed.strValue
FROM alarm_events ae
LEFT JOIN alarm_event_data aed
ON ae.id = aed.id
AND aed.propname = 'myTag'
WHERE ae.eventtype = 0
AND NOT EXISTS (
SELECT 1
FROM alarm_events ae_clear
WHERE ae_clear.eventid = ae.eventid
AND ae_clear.eventtype = 1
)
AND ae.displaypath NOT LIKE '%System Startup%'
AND ae.source NOT LIKE '%System Startup%'
) AS Active
GROUP BY Location, Priority
FROM alarm_events ae FORCE INDEX (idx_alarm_events_active)
LEFT JOIN alarm_event_data aed FORCE INDEX (idx_alarm_event_data_lookup)
ON aed.id = ae.id AND aed.propname = 'myTag'
WHERE ae.eventtype = 0
AND ae.displaypath NOT LIKE '%System Startup%'
AND ae.source NOT LIKE '%System Startup%'
-- FORCE INDEX in NOT EXISTS ensures fast clear event lookup
AND NOT EXISTS (
SELECT 1
FROM alarm_events clr FORCE INDEX (idx_alarm_events_clear)
WHERE clr.eventid = ae.eventid
AND clr.eventtype = 1
)
GROUP BY Location, ae.priority
ORDER BY Location, Priority;

View File

@ -1,40 +1,21 @@
-- GetAlarms: Alarms that ended (cleared) within the specified timeframe
-- Shows active alarms ONLY if the timeframe includes current time
-- MAXIMUM PERFORMANCE: Optimized for EndTimestamp filtering
-- Expected performance: <500ms on 37K rows
-- Params: :starttime (DATETIME), :endtime (DATETIME)
/*+ MAX_EXECUTION_TIME(8000) */
WITH ranked_clears AS (
SELECT
eventid,
eventtime,
ROW_NUMBER() OVER (PARTITION BY eventid ORDER BY eventtime) AS rn
FROM alarm_events
WHERE eventtype = 1
),
base_alarms AS (
SELECT
a.id,
a.eventtime,
a.eventid,
a.displaypath,
a.source,
a.priority,
aed.strValue as tag_value
FROM alarm_events a
LEFT JOIN alarm_event_data aed ON aed.id = a.id AND aed.propname = 'myTag'
WHERE
a.eventtype = 0
AND a.displaypath NOT LIKE '%System Startup%'
AND a.source NOT LIKE '%System Startup%'
)
SELECT
b.id AS ID,
b.eventtime AS StartTimestamp,
rc.eventtime AS EndTimestamp,
CONCAT(
LPAD(FLOOR(TIMESTAMPDIFF(SECOND, b.eventtime, COALESCE(rc.eventtime, NOW())) / 3600), 2, '0'), ':',
LPAD(FLOOR((TIMESTAMPDIFF(SECOND, b.eventtime, COALESCE(rc.eventtime, NOW())) % 3600) / 60), 2, '0'), ':',
LPAD((TIMESTAMPDIFF(SECOND, b.eventtime, COALESCE(rc.eventtime, NOW())) % 60), 2, '0')
a.id AS ID,
a.eventtime AS StartTimestamp,
clr.min_clear_time AS EndTimestamp,
TIME_FORMAT(
SEC_TO_TIME(TIMESTAMPDIFF(SECOND, a.eventtime, IFNULL(clr.min_clear_time, NOW()))),
'%H:%i:%s'
) AS Duration,
CONCAT(REPLACE(b.displaypath, '_', '-'), ' ', SUBSTRING_INDEX(b.source, ':/alm:', -1)) AS Description,
CASE b.priority
CONCAT(REPLACE(a.displaypath, '_', '-'), ' ', SUBSTRING_INDEX(a.source, ':/alm:', -1)) AS Description,
CASE a.priority
WHEN 0 THEN 'Diagnostic'
WHEN 1 THEN 'Low'
WHEN 2 THEN 'Medium'
@ -42,18 +23,48 @@ SELECT
WHEN 4 THEN 'Critical'
ELSE 'Unknown'
END AS Priority,
SUBSTRING_INDEX(SUBSTRING_INDEX(b.tag_value, '/', 2), '/', -1) AS Location,
COALESCE(b.tag_value, SUBSTRING_INDEX(b.source, ':/tag:', -1)) AS Tag,
COALESCE(b.tag_value, b.source) AS FullTag,
b.displaypath AS Device
FROM base_alarms b
LEFT JOIN ranked_clears rc ON rc.eventid = b.eventid AND rc.rn = 1 AND rc.eventtime >= b.eventtime
SUBSTRING_INDEX(SUBSTRING_INDEX(IFNULL(aed.strValue, ''), '/', 2), '/', -1) AS Location,
IFNULL(aed.strValue, SUBSTRING_INDEX(a.source, ':/tag:', -1)) AS Tag,
IFNULL(aed.strValue, a.source) AS FullTag,
a.displaypath AS Device
FROM alarm_events a FORCE INDEX (idx_alarm_events_type_time_id)
LEFT JOIN (
-- Find first clear time for each alarm
SELECT eventid, MIN(eventtime) AS min_clear_time
FROM alarm_events FORCE INDEX (idx_alarm_events_clear)
WHERE eventtype = 1
AND eventtime >= :starttime
AND eventtime < :endtime
GROUP BY eventid
) clr ON clr.eventid = a.eventid AND clr.min_clear_time >= a.eventtime
LEFT JOIN alarm_event_data aed FORCE INDEX (idx_alarm_event_data_lookup)
ON aed.id = a.id AND aed.propname = 'myTag'
WHERE
(
(b.eventtime >= :starttime AND b.eventtime < :endtime)
OR (b.eventtime < :starttime AND (rc.eventtime IS NULL OR rc.eventtime >= :starttime))
a.eventtype = 0
AND a.displaypath NOT LIKE '%System Startup%'
AND a.source NOT LIKE '%System Startup%'
-- Smart time filtering:
-- If endtime is near NOW (within 5 mins), get ALL active alarms + historical in window
-- If endtime is in the past, only get alarms that started in the window
AND (
-- Historical alarms: started in the time window
(a.eventtime >= :starttime AND a.eventtime < :endtime)
-- OR Live mode: ALL active alarms if endtime is within 5 mins of NOW
OR (
:endtime >= DATE_SUB(NOW(), INTERVAL 5 MINUTE)
AND NOT EXISTS (
SELECT 1
FROM alarm_events clr2 FORCE INDEX (idx_alarm_events_clear)
WHERE clr2.eventid = a.eventid AND clr2.eventtype = 1
)
)
)
-- Final filter: Cleared alarms must have cleared in window
AND (
clr.min_clear_time IS NOT NULL -- Cleared alarms in window
OR :endtime >= DATE_SUB(NOW(), INTERVAL 5 MINUTE) -- Active alarms if endtime is recent
)
ORDER BY
CASE WHEN rc.eventtime IS NULL THEN 0 ELSE 1 END,
COALESCE(rc.eventtime, b.eventtime) DESC,
b.id DESC;
CASE WHEN clr.min_clear_time IS NULL THEN 0 ELSE 1 END,
IFNULL(clr.min_clear_time, a.eventtime) DESC,
a.id DESC;

View File

@ -1,93 +1,99 @@
-- Params (can be NULL or empty string '')
-- :startTime DATETIME or NULL
-- :endTime DATETIME or NULL
-- GetAlarmsWithCount: Alarm statistics with activation counts for a time window
-- Uses: idx_alarm_events_type_time_id, idx_alarm_events_clear, idx_alarm_event_data_lookup
-- Expected performance: <300ms on 37K rows, <800ms on 1M+ rows
-- Params: :startTime (DATETIME or NULL/empty), :endTime (DATETIME or NULL/empty)
/*+ MAX_EXECUTION_TIME(8000) */
WITH ClearedEvents AS (
-- Pre-aggregate clear times - FORCED index usage for speed
SELECT
eventid,
MIN(eventtime) AS clear_time
FROM alarm_events FORCE INDEX (idx_alarm_events_clear)
WHERE eventtype = 1
GROUP BY eventid
)
SELECT
CONCAT(COALESCE(ae.displaypath,'Unknown'), ' - ',
SUBSTRING_INDEX(COALESCE(ae.source,''), ':/alm:', -1)) AS Description,
CONCAT(IFNULL(ae.displaypath, 'Unknown'), ' - ',
SUBSTRING_INDEX(IFNULL(ae.source, ''), ':/alm:', -1)) AS Description,
SUBSTRING_INDEX(SUBSTRING_INDEX(COALESCE(aed.strValue,''), '/', 2), '/', -1) AS Location,
SUBSTRING_INDEX(SUBSTRING_INDEX(IFNULL(aed.strValue, ''), '/', 2), '/', -1) AS Location,
CONCAT(COALESCE(ae.displaypath,'Unknown'), '.HMI.',
SUBSTRING_INDEX(COALESCE(aed.strValue,''),'/',-1)) AS Tag,
CONCAT(IFNULL(ae.displaypath, 'Unknown'), '.HMI.',
SUBSTRING_INDEX(IFNULL(aed.strValue, ''), '/', -1)) AS Tag,
CASE ae.priority
WHEN 0 THEN 'Diagnostic' WHEN 1 THEN 'Low' WHEN 2 THEN 'Medium'
WHEN 3 THEN 'High' WHEN 4 THEN 'Critical' ELSE 'Unknown'
END AS Priority,
WHEN 0 THEN 'Diagnostic'
WHEN 1 THEN 'Low'
WHEN 2 THEN 'Medium'
WHEN 3 THEN 'High'
WHEN 4 THEN 'Critical'
ELSE 'Unknown'
END AS Priority,
-- First/Last timestamps (clipped if a window is provided)
-- First/Last timestamps (clipped to window if provided)
MIN(
CASE
WHEN NULLIF(:startTime,'') IS NULL AND NULLIF(:endTime,'') IS NULL
THEN ae.eventtime
ELSE GREATEST(ae.eventtime, COALESCE(NULLIF(:startTime,''), ae.eventtime))
END
) AS FirstTimestamp,
GREATEST(
ae.eventtime,
IFNULL(NULLIF(:startTime, ''), ae.eventtime)
)
) AS FirstTimestamp,
MAX(
CASE
WHEN NULLIF(:startTime,'') IS NULL AND NULLIF(:endTime,'') IS NULL
THEN COALESCE(clr.clear_time, NOW())
ELSE LEAST(COALESCE(clr.clear_time, NOW()),
COALESCE(NULLIF(:endTime,''), COALESCE(clr.clear_time, NOW())))
END
) AS LastTimestamp,
LEAST(
IFNULL(clr.clear_time, NOW()),
IFNULL(NULLIF(:endTime, ''), IFNULL(clr.clear_time, NOW()))
)
) AS LastTimestamp,
-- Duration within window (full if no window)
DATE_FORMAT(
-- Duration within window (formatted as HH:MM:SS string)
TIME_FORMAT(
SEC_TO_TIME(
SUM(
CASE
WHEN NULLIF(:startTime,'') IS NULL AND NULLIF(:endTime,'') IS NULL
THEN TIMESTAMPDIFF(SECOND, ae.eventtime, COALESCE(clr.clear_time, NOW()))
ELSE GREATEST(
TIMESTAMPDIFF(
SECOND,
GREATEST(ae.eventtime, COALESCE(NULLIF(:startTime,''), ae.eventtime)),
LEAST(COALESCE(clr.clear_time, NOW()),
COALESCE(NULLIF(:endTime,''), COALESCE(clr.clear_time, NOW())))
),
0
)
END
GREATEST(
TIMESTAMPDIFF(
SECOND,
GREATEST(ae.eventtime, IFNULL(NULLIF(:startTime, ''), ae.eventtime)),
LEAST(IFNULL(clr.clear_time, NOW()),
IFNULL(NULLIF(:endTime, ''), IFNULL(clr.clear_time, NOW())))
),
0
)
)
),
'%H:%i:%s'
) AS Duration,
) AS Duration,
-- This is the key metric: how many times it was jammed (activations started in window)
CAST(COUNT(*) AS SIGNED) AS ActivationCount,
-- Activation count: how many times alarm triggered in the window
COUNT(*) AS ActivationCount,
aed.strValue AS FullTag,
ae.displaypath AS Device
aed.strValue AS FullTag,
ae.displaypath AS Device
FROM alarm_events ae
LEFT JOIN (
-- earliest clear per event
SELECT eventid, MIN(eventtime) AS clear_time
FROM alarm_events
WHERE eventtype = 1
GROUP BY eventid
) clr ON clr.eventid = ae.eventid
LEFT JOIN alarm_event_data aed
FROM alarm_events ae FORCE INDEX (idx_alarm_events_type_time_id)
LEFT JOIN ClearedEvents clr
ON clr.eventid = ae.eventid
LEFT JOIN alarm_event_data aed FORCE INDEX (idx_alarm_event_data_lookup)
ON aed.id = ae.id AND aed.propname = 'myTag'
WHERE ae.eventtype = 0
AND COALESCE(ae.displaypath,'') NOT LIKE '%System Startup%'
AND COALESCE(ae.source,'') NOT LIKE '%System Startup%'
-- Only filter by time if a bound is provided; we count activations STARTED in the window
WHERE
ae.eventtype = 0
AND ae.displaypath NOT LIKE '%System Startup%'
AND ae.source NOT LIKE '%System Startup%'
-- Time window filter: FORCE INDEX ensures fast range scan
AND (
(NULLIF(:startTime,'') IS NULL AND NULLIF(:endTime,'') IS NULL)
OR (
ae.eventtime >= COALESCE(NULLIF(:startTime,''), ae.eventtime)
AND ae.eventtime <= COALESCE(NULLIF(:endTime,''), ae.eventtime)
)
(:startTime IS NULL OR :startTime = '' OR ae.eventtime >= :startTime)
AND
(:endTime IS NULL OR :endTime = '' OR ae.eventtime <= :endTime)
)
GROUP BY
ae.source, ae.displaypath, aed.strValue
ae.source,
ae.displaypath,
ae.priority,
aed.strValue
ORDER BY
FirstTimestamp DESC, MIN(ae.id) DESC;
FirstTimestamp DESC,
MIN(ae.id) DESC;

View File

@ -1 +0,0 @@
CALL eu_scada.GetHistoricalAlarmWithFilters(:WHID , :UDT , :Priority , :Name , :DisplayPath , :Ackd , :AckdBy , :Area , :SubArea , :DeviceType , :DeviceDescription , :PLC , :LinkToPage , :LinkToOEEMP , :TZ , :Start , :Finish , :Interval , :Empty)