From 98268ffc8dbf8a5b2c31773202728027ea465ae4 Mon Sep 17 00:00:00 2001 From: "gigi.mamaladze" Date: Sat, 11 Oct 2025 21:05:45 +0400 Subject: [PATCH] Updated Parent project + Scripts --- CNO8_SCADA/ignition/event-scripts/data.bin | Bin 1235 -> 2919 bytes .../views/Alarm-Views/RealTime/view.json | 50 ++++--- .../views/Header/Header/view.json | 4 +- .../Navigation-Views/Docked-West/view.json | 2 +- .../ignition/event-scripts/data.bin | Bin 1195 -> 1196 bytes .../ignition/global-props/data.bin | Bin 593 -> 591 bytes .../named-query/GetActiveAlarms/query.sql | 43 +++--- .../query.sql | 43 +++--- .../ignition/named-query/GetAlarms/query.sql | 101 +++++++------ .../named-query/GetAlarmsWithCount/query.sql | 140 +++++++++--------- .../GetHistoricalAlarms/query.sql | 1 - 11 files changed, 206 insertions(+), 178 deletions(-) delete mode 100644 SCADA_PERSPECTIVE_PARENT_PROJECT/ignition/named-query/StoredProcedures/GetHistoricalAlarms/query.sql diff --git a/CNO8_SCADA/ignition/event-scripts/data.bin b/CNO8_SCADA/ignition/event-scripts/data.bin index 556b357dc81e3b097b43444740f14152c0942d31..e42df0f1ff1bf1f117b12779a455c1e337ae9abd 100644 GIT binary patch literal 2919 zcmV-t3z+mDiwFP!00000|IHa)bKA!8WIM4;$F&{DiQ_oQhKg*$reIPZw!*}jp-EU~ zOpyu!x$$^390)v-ut9*uhiLXcbo$n5|3Y6n(;tzU_Nfp3FMVwH?f?+rhb^gUrX0)n zf!)2`z1_XNy+2C7|8wPEKQ#aPyT5<;^bdde8zJNjAq#){=luI3cf1il%XM|{m z)0a)V6BxdENcF&X`nqpAwrqB7lXnoHk4@m4mi)xDeCpDUrgtkn-R{!5>G{;A?$_~* zHX2YQ{S8_8dCAwiUfXxtF4a5m2)q#j_hp=w+00|hF6Y&H1@w3|&i5|Md0MQ!ZeA>`pv%}$V(HMY((IzsFvLN2}14|TD#+xh_KvV>gr zsL!EM z!5kqMUHY4VdcJDtOq3!M%I;$C146Db79u|wv+@3cfA@8d zLbzBSG=1Mu1H^_xvw{211t`H<0e{fxd4^TqW zVk9|)&%Vbl(%I*eA#Uveh7`~ap@*)XpG5=t9=MJ{X=jW$a7{GY?4vB)g$D&GIae)f z<;P`J0aejXIa-$i;poyMevS zgW`{j!5n831M{}-ntJtdR(dxV>Tac?sOpi{7KZ~Uyuly}x(75ZsW>P4UYEJQ@8)Ql z1&kS4`UVg6ELUa(EL+YHj}<9RYc9_`cHz;*BJKz{Jv83tGwH}0q?SjIxY(0&t*%r{ zuFT4wdd%~jjHlf9B{NA#Sp)Vs^vi*4CfHf0^PF2 zF%KcTQ55Gk!-7|tpORrN0J%hbz_7p$H=u{q_B|0lBv z0-j`eDTK8WJjJcT?}lzgs|`)RhyU3fX9x#@Z7?cnwDl4{mk`r5LU@)I#7I16L_Z3V z!e)oM=(~O0HYk|=fo}Mb*ehefHwr7oLg5V@=;%-`qzQPGceSvxkpS;9@p0uz z$TfCst~^LUP6{}QfikWaRyGqDNfBAf6r-H#sggb;L%jG;!SU*_p=; z=MQbQrqwFtdSsvQq}hUUy$(O_DySlDvg$BRUpX}OIDU9$nnk2&5jh`ca;1{Zc& z=4*DOY<`vitMY_1adWLIY6Tp(!_5?Op#YJVx#OHrh|pkM_yAk2 zCg!$}Uz||Q5#_g;N(3`$G;;)Ej=rO`(6zVAjfw(~n@v@VJ${adKR_#ErxKH$M-iT3 z;bm-KVL#feT*A0k5YDiI4oZX9wL|ncuwFNG#o_AoTI#lGE@bD9VC!6h#s{DVce+Ko+)r=SyU?6A?W(SVEGQq z!>qs?pCiW>I>Gyt=#z5I5nxjWg&{z#8itDTwoRSqV>7O3%1N0HwSRle~ZX8oMfMAo08eo9$?TJ(F5p!jYkXIu*AvUWO` zf@(0ZFfH_H`eJ~m=FAJj{M!R>hr5{0qv+oi~+nPd|%kb>WMw-JpmyNd+ zNZ6gBu4qarD*u2gM0&K0ZlmxDA9neYDPi+TF{EFto`U(as%W6TXjE7=N843FD{q0; zWRfQ)ifKL9v3UyZV^ZQf$oe>mj(+I^ zir#JWi2Mk$FDs4aW?QY4tK~L|-ri|7pVz8NYcH%?Ppy)j6)IRIoR@^hrSNExy*#|s z+<@-Ag`rR~mQ;Dv7cxMOVM+7km=z4zl3brN^`^91csKAu?ICOlvY1`6FcBk$mX~(4 z5WnI0N$ilzPC!{t6t7w25V?lIgRf&pcbSmg24-#C3lgy_$zCZcQudurU{SDf&A3=O z=9eO$Z;6JHGe&o#kaPl@5VA2avq5@P2%V-eiFrc9DJRsfIro}o+zq+MaWJaL2P3r zhiyf-jKC6=dTTtDlQI*4<-=|gHXL%c){zX&8AL zjZ^%VkOF%O8SZ<=Yrn1U<8@RvEXSkmA?0)IwM9ea@hUd2ej^$X@>$4k{K|x62P5$& zgb=HQWRSv&hu+B_1>Q%ktGW+O!-rxKRtu$#VrlguY+*E9EvzEv+pQTTmqGuRr~t{|lY9UV%%=w02Ei}Lz6GFzmuSzImP z=90^}l>DI)8kF-FINfq{DL(~ zat_%q7KL(Af8=8vvo|CD{RR;{k%dLE4dm>iz#;D~3UeR}4Cwp<3k?^9F38!NLVF~` zP%bWt*CBE#vmio(z`4vuSI+!9q(80WKyiCbrqQ=hY`FODVam+zEyLcDxAjiHyO ztpGzRd4C#bnd7kG?eK46*Y7Y=$I?VDIgn1ciwFP!00000|IJlfPa8)RKIT%)(v%Q#A%r9wJ0UiK!FC{AdXZ9-5VdKE zWG8)yqSde-?1lBNJ2Pv?f1y&4gFDs)45&RH!3~r00{zo-Y|^l`^dsYc!~`r=E~3VElGRQf@aGLT^Cg_q3!{ z;mFY8j8^PVZP7;MIzcH>lF$9nJ@SHT=4GlF1_xd>;@b7<<6>&rPL;IwDs2g;LM2VT z%3A4G%~L?VxG!_BNR#>zv(nV3yl%9+-gMlDA`Etz8&+7R&o&?1BD9s3yuEFuCxxUk z5(x0Z6A|@2Vd`PTWS7a3<}xalWxK~`wqs28BhRlm=8@@Wg=baOJt?wa<3s%SEu zHc*xVm=;WGEmH!O%RM74)u@{4ni>j}t^y=cy2E^`;I0D9bm1NaQN6@exEX*c&c2P9 zkR_L@u=6T`po-jw0JF;7@mh3UCQ--r6}JE|#t;qJOUC0fDr@S?Eb0i!k^2aLyS~-B zp)i2~9dKG_t&ks)CgTFjf$~k0&2wF2;}NA7v9LQ~EAT^FacYPVa+MX9ej(nG1`kzp zNl!AmGY_!YW*qQw0fzv=zeczCTEb7Jm-x8dSD+_U)J)B90X%z(DuLT3F)dQxjeOHc zzbnFZIHCBkS?$%0pE|5H3`Xrq95(KYx*qsp5lgd&6i0B$2uZ&V88p*~TL3w=Os#$4 z9!ZDphg=fZ4+V2tOv}{1ma%v?{!&{q-3J>_XdG_mP9bcgZLSJx6aXwlSP^*Y^vsL{ zOsb8*ves3JZr}{PP|9XZP%?)d$2xbfsVe?5X10&iLh2%2L8Jrf3uX@f%qGc`wJoC7 zFSnU5awi9R`BArK8 zO|j7V-Nez4`|7yVSNz7BD(*st1-bnM#^# z0q3lQ*>__ztzPFx{)v%C`f+AX$GOnKnN>J;%&3Si4r*WO_nPeY3WElh&xXG;7~j|+ zz+4C5>T#a)9h+;%K`e~)imofsjiGYA`LDU2sBq#Wf<097w+6LS9qshs6yUvt@j;tA z+D1JW)$?l{_Rh{0>B7B;`=`iF8=_7pIv-!8um6o$qj473(Aozy#}L^ z3~N++VL-e};AsXGYDgmK`Q(}BOU7BbL@R|V4Jzz~CnO6PUu;WCtvW;K_W%}(RN9BG zwDWm8zrDAyv$wTjA3QDD>$&wURM~>WFKJ0D!jYlF87TNdH!QPEk8M7-MQAH6d27!~PY6k6BoN@0CnD;5!j#O2$pMo^&1F<9D|VO9 zY}=R|MV?=F%pubyZ*osEt*oWSm}ug-VH8MGVbX8|@vSs_>$1AUIBk3$e^n%m^Nr+1t{~^L0J(<%JO6ev4Kyh!KcBG{TBiY~PH2Og&VEko zC`$oM3nsOe$xj8EHPT|0s;RE3j-zxHAc@j_=2HcC3t*-L_cVxVMW(`CQ{e^`BtUTV$^r{FhW#)t6b+5t1W!8Gjv5YPnFDK=;R-)>t#-r=-ES zz~oWBZDRjYSJZe!=`}3le%K8Bkd~b)B7|J!u!$>a+J=X#*etaC0x|KF!B3_wcv$So z^*I$)Q@;BEFJGWa;I>Fi3)FWb-}J=qh;VGrDL!sgx^?5D?)^FjqvpBJLp3`%*J{i0 z!xH9wh;##B*$7Fm4(T`3h&uo|HT2CR;hsu|9)(;I*AE4AnoP^oUX`#iHvXtBnJ%)8 zw_zM^`#wR~ddqA-YUBVcL|7GgCF%BG0+>+4jb*K=65R!ue5I7l44`BV+lh7VT#Tyt z%b3{_QVXez^bsN*Q(rK1chBsSJlXt!s7o@pn_thV`+6E(QO;@0HzPsN)<-&tR1MS} zq-rGc80G~l>(Vk+6>v=aJsUWV<{{E~WYvfYo!>p2>$tCuOMT^U0^q|T*U}7T;jFJy z=t@;#6kB`|Qo|FPv?qNA;FDo*gWgp{kTDEDpEt$DUcwDLtJT-v=fK1SiKJ-*j3$i@ zTuPe1Ge{_<@q}9H2~!Igoj273OPNe2%~b$XR>CZ^v6)tlD zzy^%tYTFe#3k?7MU_y@y`<@FYp1E5CKKDa5-w74+Eh?T zC7br4s#fFm#NK4RYt78s^^ZWjA@~ctAovSNmEehA1CMZKXMKwufl(h=t#!_vJ?A_3 z@pqYTeklC;+0oBm|Mt<-Z-4w1044xp-~aOVkDp-lvxmRyn!O27vi&-7yh>n8r^#p_ z{W_J7?-8f!IU$1zbtHjwT=K+mCF878qSZo;dR6w!5t4a~FLx!Sc7q}GHpJehB&`Zd z`W9!jVt#CjHY(Q%N{Nzu>iYJn<5knIk_F#8cB%mnU2i-oB-hMjG1T6mEn!utq{-JA zBh{)o3aB6VRrWP$Qa4~min^57wRX>2825?ry#r?Z6_y^b%|*5dZKNb`?;ELvkW>Z& z0bV#FpspiyJ+zn{GFc3{w2EcT?DLuF8k2J1xD`tu(tYw4cO(myL#Z|Wo_=l#3`)i@jlXAXz%2M`hYCpD;?5AQ{ir?aJ?#W?*S|*@Xmzy9K=z_b`^IEV2YtFvR5_!b1G}<%L3{M z$&q^>-<~J6IVg;w`(sY)tmX4l(qvp<@+jZYv40g-RC`3}6)fX{-|}3aR;(H#_*~_% z1#nTf4G)*GS!nqsV&W-{pLARBuso3KQz~k@eD?sJKSLGIZj*=>sA~tV?upwI;n<#0 zeAKM=>qf`0_jwFP&2xkMYIbn0)t2Lj70mkx=_bIc7Lq|7GHezi?gC`h(6`FMK9v?N z`&<&+^#!w9ER?CeDq&?ze5ol}SY#8gx+vW4eS)x!w%&f!$O0IMurBaQ3fq4HAfbjE z%UV|@x&tutLMiJRK*=Ju6YJc&^;Gd!F|#sK1F4PlAtD`9S1^4s&+m~O+4_Lwv-$1p zUM`6BqMXyVt4HD@j?+t4F^_C%X7|k8&VGJ#e=BPqJ}#Nc5LF1myGUn{s+qfu zR836|GdX9gZCatKNS01ls5H1Su2JTZtfKN{z97iU4? zm=U8Qx-zVNbddiNi5 zJyYS>Sp;*e1wY=nZv_=lePaC z*objl@46zL!0;au65)8E^6z8ik{v&n+`B9CyUiuvf7txLR(xyxif<2_?40jl_isF0 J*{6#P002&(PTc?i diff --git a/SCADA_PERSPECTIVE_PARENT_PROJECT/ignition/global-props/data.bin b/SCADA_PERSPECTIVE_PARENT_PROJECT/ignition/global-props/data.bin index d5c7981b59b3cc76b40e20bbb6462982e5f75dc7..26f9fbe22036a428c59824febd3c2c47faaa804c 100644 GIT binary patch literal 591 zcmV-V0IMs;HB_*W zZpmfl0=J!E$jlu~AHujZ`U-ALd<$LpI&S@6E>fGZB$IRI-rxE9pW*YNY*cs7V~0hcvCV4)*xOtQcWeT%ymie zLK{fifL;)P?U8FcaO3*>Jo*bI{sE z$*_YW1Lg!=Yn-l_Mf3Tgsp=Oh#ZsYy^E4(rW4>Uu*LX`nAInj(tLVa2s=|7(4{#Gm zA6^#IL4{LWHNA#wg&!b7vf;Cl2&Cs<5zNd2 z&LH#6);sT-T{a9b-c;D!pYL=NgLbOj!(QjOTC4WD)kd#<-nuxg)z5L8!!0tjx$lZV zWv!1{-{H1i(>=&sENWQ_InwQsk9*x+z9g&|qicUxA%-!^6l+NC!l|xZ#Ye8-6?LoLGm0M7|Q8g59 dL}T`6F){t8n?13AJ3g3|`U7_?2V55f005i5BYXe= literal 593 zcmV-X0LZAFMzIuj1YO|JPbMMTYbMLulhR;tvel7og)A;`3 z=gZ?y-+mC$0+I3M*Sptc`v31CzBQt>&t--8SzyZwlgxJm&*Epy;TpBV^8gEZ3)eD?15$(5_%rq>S$>lQH{L$gFqe3B5tF|-wZ2l0C z`$Q>pD+O}c^xVF%|MuAd-Y=;~?B zSZ!hsl&$jtv#wEC>BaUAQR1eACN2`iq;R+|nWNTQXxBxIBU*?tq8FCym}1lmEGZ_O z1=4kx6z<3rgOQjf05}L^-N~%kZkO5UJ60xbqe-9HKG!#pESfp9@Z3}mWQ)0cwut>C z=nI9BijFeDp19SUE%-Zgd% z)b4xm^u6m{nG^2$(2M;D(c` 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; \ No newline at end of file diff --git a/SCADA_PERSPECTIVE_PARENT_PROJECT/ignition/named-query/GetActiveAlarmsByLocationAndPriority/query.sql b/SCADA_PERSPECTIVE_PARENT_PROJECT/ignition/named-query/GetActiveAlarmsByLocationAndPriority/query.sql index d8872f4..975eb06 100644 --- a/SCADA_PERSPECTIVE_PARENT_PROJECT/ignition/named-query/GetActiveAlarmsByLocationAndPriority/query.sql +++ b/SCADA_PERSPECTIVE_PARENT_PROJECT/ignition/named-query/GetActiveAlarmsByLocationAndPriority/query.sql @@ -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; diff --git a/SCADA_PERSPECTIVE_PARENT_PROJECT/ignition/named-query/GetAlarms/query.sql b/SCADA_PERSPECTIVE_PARENT_PROJECT/ignition/named-query/GetAlarms/query.sql index 9d3afe1..8e7204f 100644 --- a/SCADA_PERSPECTIVE_PARENT_PROJECT/ignition/named-query/GetAlarms/query.sql +++ b/SCADA_PERSPECTIVE_PARENT_PROJECT/ignition/named-query/GetAlarms/query.sql @@ -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; \ No newline at end of file + CASE WHEN clr.min_clear_time IS NULL THEN 0 ELSE 1 END, + IFNULL(clr.min_clear_time, a.eventtime) DESC, + a.id DESC; \ No newline at end of file diff --git a/SCADA_PERSPECTIVE_PARENT_PROJECT/ignition/named-query/GetAlarmsWithCount/query.sql b/SCADA_PERSPECTIVE_PARENT_PROJECT/ignition/named-query/GetAlarmsWithCount/query.sql index cebf6c6..95bb081 100644 --- a/SCADA_PERSPECTIVE_PARENT_PROJECT/ignition/named-query/GetAlarmsWithCount/query.sql +++ b/SCADA_PERSPECTIVE_PARENT_PROJECT/ignition/named-query/GetAlarmsWithCount/query.sql @@ -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; \ No newline at end of file diff --git a/SCADA_PERSPECTIVE_PARENT_PROJECT/ignition/named-query/StoredProcedures/GetHistoricalAlarms/query.sql b/SCADA_PERSPECTIVE_PARENT_PROJECT/ignition/named-query/StoredProcedures/GetHistoricalAlarms/query.sql deleted file mode 100644 index 53a1f49..0000000 --- a/SCADA_PERSPECTIVE_PARENT_PROJECT/ignition/named-query/StoredProcedures/GetHistoricalAlarms/query.sql +++ /dev/null @@ -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) \ No newline at end of file