mirror of
https://github.com/jokob-sk/NetAlertX.git
synced 2025-12-07 09:36:05 -08:00
indexes 4 the win
This commit is contained in:
@@ -63,7 +63,11 @@
|
||||
|
||||
// some race condition, need to implement delay
|
||||
setTimeout(() => {
|
||||
$.get('php/server/query_json.php', { file: 'table_settings.json', nocache: Date.now() }, function(res) {
|
||||
$.get('php/server/query_json.php', {
|
||||
file: 'table_settings.json',
|
||||
// nocache: Date.now()
|
||||
},
|
||||
function(res) {
|
||||
|
||||
settingsData = res["data"];
|
||||
|
||||
|
||||
@@ -1,8 +1,6 @@
|
||||
<?php
|
||||
|
||||
require 'php/templates/header.php';
|
||||
require 'php/templates/notification.php';
|
||||
|
||||
?>
|
||||
|
||||
<script>
|
||||
|
||||
@@ -121,93 +121,87 @@ function getServerDeviceData() {
|
||||
}
|
||||
|
||||
|
||||
// Device Data
|
||||
$sql = 'SELECT rowid, *,
|
||||
CASE WHEN devAlertDown !=0 AND devPresentLastScan=0 THEN "Down"
|
||||
WHEN devPresentLastScan=1 THEN "On-line"
|
||||
ELSE "Off-line" END as devStatus
|
||||
FROM Devices
|
||||
WHERE devMac="'. $mac .'" or cast(rowid as text)="'. $mac. '"';
|
||||
$result = $db->query($sql);
|
||||
$row = $result -> fetchArray (SQLITE3_ASSOC);
|
||||
// Get current date (used in presence calc)
|
||||
$currentdate = date("Y-m-d H:i:s");
|
||||
|
||||
// Fetch Device Info + Children + Events Stats
|
||||
$sql =<<<SQL
|
||||
SELECT
|
||||
d.rowid,
|
||||
d.*,
|
||||
CASE
|
||||
WHEN d.devAlertDown != 0 AND d.devPresentLastScan = 0 THEN "Down"
|
||||
WHEN d.devPresentLastScan = 1 THEN "On-line"
|
||||
ELSE "Off-line"
|
||||
END AS devStatus,
|
||||
|
||||
-- Event counters
|
||||
(SELECT COUNT(*) FROM Sessions
|
||||
WHERE ses_MAC = d.devMac AND (
|
||||
ses_DateTimeConnection >= $periodDate OR
|
||||
ses_DateTimeDisconnection >= $periodDate OR
|
||||
ses_StillConnected = 1
|
||||
)
|
||||
) AS devSessions,
|
||||
|
||||
(SELECT COUNT(*) FROM Events
|
||||
WHERE eve_MAC = d.devMac AND
|
||||
eve_DateTime >= $periodDate AND
|
||||
eve_EventType NOT IN ("Connected", "Disconnected")
|
||||
) AS devEvents,
|
||||
|
||||
(SELECT COUNT(*) FROM Events
|
||||
WHERE eve_MAC = d.devMac AND
|
||||
eve_DateTime >= $periodDate AND
|
||||
eve_EventType = "Device Down"
|
||||
) AS devDownAlerts,
|
||||
|
||||
(SELECT CAST(( MAX (0, SUM (julianday (IFNULL (ses_DateTimeDisconnection,'$currentdate'))
|
||||
- julianday (CASE WHEN ses_DateTimeConnection < $periodDate
|
||||
THEN $periodDate
|
||||
ELSE ses_DateTimeConnection END)) *24 )) AS INT)
|
||||
FROM Sessions
|
||||
WHERE ses_MAC = d.devMac AND
|
||||
ses_DateTimeConnection IS NOT NULL AND
|
||||
(ses_DateTimeDisconnection IS NOT NULL OR ses_StillConnected = 1) AND
|
||||
(
|
||||
ses_DateTimeConnection >= $periodDate OR
|
||||
ses_DateTimeDisconnection >= $periodDate OR
|
||||
ses_StillConnected = 1
|
||||
)
|
||||
) AS devPresenceHours
|
||||
|
||||
FROM Devices d
|
||||
WHERE d.devMac = "$mac" OR CAST(d.rowid AS TEXT) = "$mac"
|
||||
SQL;
|
||||
|
||||
$row = $db->query($sql)->fetchArray(SQLITE3_ASSOC);
|
||||
$deviceData = $row;
|
||||
$mac = $deviceData['devMac'];
|
||||
|
||||
$deviceData['devParentMAC'] = $row['devParentMAC'];
|
||||
$deviceData['devParentPort'] = $row['devParentPort'];
|
||||
$deviceData['devFirstConnection'] = formatDate ($row['devFirstConnection']); // Date formated
|
||||
$deviceData['devLastConnection'] = formatDate ($row['devLastConnection']); // Date formated
|
||||
|
||||
$deviceData['devFirstConnection'] = formatDate($deviceData['devFirstConnection']);
|
||||
$deviceData['devLastConnection'] = formatDate($deviceData['devLastConnection']);
|
||||
$deviceData['devIsRandomMAC'] = isRandomMAC($mac);
|
||||
|
||||
// devChildrenDynamic
|
||||
$sql = 'SELECT rowid, * FROM Devices WHERE devParentMAC = "' . $mac . '" order by devPresentLastScan DESC';
|
||||
// Fetch children once and split in PHP
|
||||
$sql = 'SELECT rowid, * FROM Devices WHERE devParentMAC = "' . $mac . '" ORDER BY devPresentLastScan DESC';
|
||||
$result = $db->query($sql);
|
||||
|
||||
$children = [];
|
||||
if ($result) {
|
||||
$childrenNics = [];
|
||||
|
||||
while ($row = $result->fetchArray(SQLITE3_ASSOC)) {
|
||||
$children[] = $row;
|
||||
}
|
||||
}
|
||||
$deviceData['devChildrenDynamic'] = $children;
|
||||
|
||||
// devChildrenNicsDynamic
|
||||
$sql = 'SELECT rowid, * FROM Devices WHERE devParentMAC = "' . $mac . '" and devParentRelType = "nic" order by devPresentLastScan DESC';
|
||||
$result = $db->query($sql);
|
||||
|
||||
$childrenNics = [];
|
||||
if ($result) {
|
||||
while ($row = $result->fetchArray(SQLITE3_ASSOC)) {
|
||||
if ($row['devParentRelType'] === 'nic') {
|
||||
$childrenNics[] = $row;
|
||||
}
|
||||
}
|
||||
|
||||
$deviceData['devChildrenDynamic'] = $children;
|
||||
$deviceData['devChildrenNicsDynamic'] = $childrenNics;
|
||||
|
||||
// Count Totals
|
||||
$condition = ' WHERE eve_MAC="'. $mac .'" AND eve_DateTime >= '. $periodDate;
|
||||
// Return JSON
|
||||
echo json_encode($deviceData);
|
||||
|
||||
// Connections
|
||||
$sql = 'SELECT COUNT(*) FROM Sessions
|
||||
WHERE ses_MAC="'. $mac .'"
|
||||
AND ( ses_DateTimeConnection >= '. $periodDate .'
|
||||
OR ses_DateTimeDisconnection >= '. $periodDate .'
|
||||
OR ses_StillConnected = 1 )';
|
||||
$result = $db->query($sql);
|
||||
$row = $result -> fetchArray (SQLITE3_NUM);
|
||||
$deviceData['devSessions'] = $row[0];
|
||||
|
||||
// Events
|
||||
$sql = 'SELECT COUNT(*) FROM Events '. $condition .' AND eve_EventType <> "Connected" AND eve_EventType <> "Disconnected" ';
|
||||
$result = $db->query($sql);
|
||||
$row = $result -> fetchArray (SQLITE3_NUM);
|
||||
$deviceData['devEvents'] = $row[0];
|
||||
|
||||
// Down Alerts
|
||||
$sql = 'SELECT COUNT(*) FROM Events '. $condition .' AND eve_EventType = "Device Down"';
|
||||
$result = $db->query($sql);
|
||||
$row = $result -> fetchArray (SQLITE3_NUM);
|
||||
$deviceData['devDownAlerts'] = $row[0];
|
||||
|
||||
// Get current date using php, sql datetime does not return time respective to timezone.
|
||||
$currentdate = date("Y-m-d H:i:s");
|
||||
// Presence hours
|
||||
$sql = 'SELECT CAST(( MAX (0, SUM (julianday (IFNULL (ses_DateTimeDisconnection,"'. $currentdate .'" ))
|
||||
- julianday (CASE WHEN ses_DateTimeConnection < '. $periodDate .' THEN '. $periodDate .'
|
||||
ELSE ses_DateTimeConnection END)) *24 )) AS INT)
|
||||
FROM Sessions
|
||||
WHERE ses_MAC="'. $mac .'"
|
||||
AND ses_DateTimeConnection IS NOT NULL
|
||||
AND (ses_DateTimeDisconnection IS NOT NULL OR ses_StillConnected = 1 )
|
||||
AND ( ses_DateTimeConnection >= '. $periodDate .'
|
||||
OR ses_DateTimeDisconnection >= '. $periodDate .'
|
||||
OR ses_StillConnected = 1 )';
|
||||
$result = $db->query($sql);
|
||||
$row = $result -> fetchArray (SQLITE3_NUM);
|
||||
$deviceData['devPresenceHours'] = round ($row[0]);
|
||||
|
||||
// Return json
|
||||
echo (json_encode ($deviceData));
|
||||
}
|
||||
|
||||
|
||||
|
||||
@@ -10,7 +10,7 @@ from const import fullDbPath, sql_devices_stats, sql_devices_all, sql_generateGu
|
||||
from logger import mylog
|
||||
from helper import json_obj, initOrSetParam, row_to_json, timeNowTZ
|
||||
from workflows.app_events import AppEvent_obj
|
||||
from db.db_upgrade import ensure_column, ensure_views, ensure_CurrentScan, ensure_plugins_tables, ensure_Parameters, ensure_Settings
|
||||
from db.db_upgrade import ensure_column, ensure_views, ensure_CurrentScan, ensure_plugins_tables, ensure_Parameters, ensure_Settings, ensure_Indexes
|
||||
|
||||
class DB():
|
||||
"""
|
||||
@@ -111,6 +111,9 @@ class DB():
|
||||
# Views
|
||||
ensure_views(self.sql)
|
||||
|
||||
# Views
|
||||
ensure_Indexes(self.sql)
|
||||
|
||||
# commit changes
|
||||
self.commitDB()
|
||||
|
||||
|
||||
@@ -153,6 +153,61 @@ def ensure_views(sql) -> bool:
|
||||
|
||||
return True
|
||||
|
||||
def ensure_Indexes(sql) -> bool:
|
||||
"""
|
||||
Ensures required indexes exist with correct structure.
|
||||
|
||||
Parameters:
|
||||
- sql: database cursor or connection wrapper (must support execute()).
|
||||
"""
|
||||
indexes = [
|
||||
# Sessions
|
||||
("idx_ses_mac_date",
|
||||
"CREATE INDEX idx_ses_mac_date ON Sessions(ses_MAC, ses_DateTimeConnection, ses_DateTimeDisconnection, ses_StillConnected)"),
|
||||
|
||||
# Events
|
||||
("idx_eve_mac_date_type",
|
||||
"CREATE INDEX idx_eve_mac_date_type ON Events(eve_MAC, eve_DateTime, eve_EventType)"),
|
||||
("idx_eve_alert_pending",
|
||||
"CREATE INDEX idx_eve_alert_pending ON Events(eve_PendingAlertEmail)"),
|
||||
("idx_eve_mac_datetime_desc",
|
||||
"CREATE INDEX idx_eve_mac_datetime_desc ON Events(eve_MAC, eve_DateTime DESC)"),
|
||||
("idx_eve_pairevent",
|
||||
"CREATE INDEX idx_eve_pairevent ON Events(eve_PairEventRowID)"),
|
||||
("idx_eve_type_date",
|
||||
"CREATE INDEX idx_eve_type_date ON Events(eve_EventType, eve_DateTime)"),
|
||||
|
||||
# Devices
|
||||
("idx_dev_mac", "CREATE INDEX idx_dev_mac ON Devices(devMac)"),
|
||||
("idx_dev_present", "CREATE INDEX idx_dev_present ON Devices(devPresentLastScan)"),
|
||||
("idx_dev_alertdown", "CREATE INDEX idx_dev_alertdown ON Devices(devAlertDown)"),
|
||||
("idx_dev_isnew", "CREATE INDEX idx_dev_isnew ON Devices(devIsNew)"),
|
||||
("idx_dev_isarchived", "CREATE INDEX idx_dev_isarchived ON Devices(devIsArchived)"),
|
||||
("idx_dev_favorite", "CREATE INDEX idx_dev_favorite ON Devices(devFavorite)"),
|
||||
("idx_dev_parentmac", "CREATE INDEX idx_dev_parentmac ON Devices(devParentMAC)"),
|
||||
|
||||
# Optional filter indexes
|
||||
("idx_dev_site", "CREATE INDEX idx_dev_site ON Devices(devSite)"),
|
||||
("idx_dev_group", "CREATE INDEX idx_dev_group ON Devices(devGroup)"),
|
||||
("idx_dev_owner", "CREATE INDEX idx_dev_owner ON Devices(devOwner)"),
|
||||
("idx_dev_type", "CREATE INDEX idx_dev_type ON Devices(devType)"),
|
||||
("idx_dev_vendor", "CREATE INDEX idx_dev_vendor ON Devices(devVendor)"),
|
||||
("idx_dev_location", "CREATE INDEX idx_dev_location ON Devices(devLocation)"),
|
||||
|
||||
# Settings
|
||||
("idx_set_key", "CREATE INDEX idx_set_key ON Settings(setKey)")
|
||||
]
|
||||
|
||||
for name, create_sql in indexes:
|
||||
sql.execute(f"DROP INDEX IF EXISTS {name};")
|
||||
sql.execute(create_sql + ";")
|
||||
|
||||
return True
|
||||
|
||||
|
||||
|
||||
|
||||
|
||||
def ensure_CurrentScan(sql) -> bool:
|
||||
"""
|
||||
Ensures required CurrentScan table exist.
|
||||
|
||||
Reference in New Issue
Block a user