summaryrefslogtreecommitdiffstats
path: root/modules-available/statistics_reporting/inc/queries.inc.php
diff options
context:
space:
mode:
authorUdo Walter2017-01-12 12:41:21 +0100
committerUdo Walter2017-01-12 12:41:21 +0100
commit9ccef127acd6dca0971e12726b019e2beaf7e4ce (patch)
tree506f14129c595665e00714bac2b1c9794342457e /modules-available/statistics_reporting/inc/queries.inc.php
parent[statistics_reporting] improved readability, added hashed values to queries (diff)
downloadslx-admin-9ccef127acd6dca0971e12726b019e2beaf7e4ce.tar.gz
slx-admin-9ccef127acd6dca0971e12726b019e2beaf7e4ce.tar.xz
slx-admin-9ccef127acd6dca0971e12726b019e2beaf7e4ce.zip
[statistics_reporting] moved some functions to a new class
Diffstat (limited to 'modules-available/statistics_reporting/inc/queries.inc.php')
-rw-r--r--modules-available/statistics_reporting/inc/queries.inc.php153
1 files changed, 153 insertions, 0 deletions
diff --git a/modules-available/statistics_reporting/inc/queries.inc.php b/modules-available/statistics_reporting/inc/queries.inc.php
new file mode 100644
index 00000000..23afceed
--- /dev/null
+++ b/modules-available/statistics_reporting/inc/queries.inc.php
@@ -0,0 +1,153 @@
+<?php
+
+
+class Queries
+{
+
+ // Client Data: Name, Time Online, Median Time Online, Time Offline, last start, last logout, Last Time Booted, Number of Sessions > 60Sec, Number of Sessions < 60Sec, name of location, id of location (anonymized), machine uuid (anonymized)
+ public static function getClientStatistics($cutOff, $lowerTimeBound = 0, $upperTimeBound = 24) {
+ $notassigned = Dictionary::translateFile('template-tags', 'lang_notassigned');
+ $res = Database::simpleQuery("SELECT t1.name AS clientName, timeSum, medianTime, offlineSum, lastStart, lastLogout, longSessions, shortSessions, locName, MD5(locId) AS locHash, MD5(t1.uuid) AS clientHash FROM (
+ SELECT machine.hostname AS 'name', machine.machineuuid AS 'uuid', SUM(CAST(sessionTable.length AS UNSIGNED)) AS 'timeSum', GROUP_CONCAT(sessionTable.length) AS 'medianTime', SUM(sessionTable.length >= 60) AS 'longSessions', SUM(sessionTable.length < 60) AS 'shortSessions',MAX(sessionTable.dateline + sessionTable.data) AS 'lastLogout', IFNULL(location.locationname, '$notassigned') AS 'locName', location.locationid AS 'locId'
+ FROM ".self::getBoundedTableQueryString('~session-length', $lowerTimeBound, $upperTimeBound, $cutOff)." sessionTable
+ INNER JOIN machine ON sessionTable.machineuuid = machine.machineuuid
+ LEFT JOIN location ON machine.locationid = location.locationid
+ GROUP BY machine.machineuuid
+ ) t1
+ INNER JOIN (
+ SELECT machine.hostname AS 'name', machine.machineuuid AS 'uuid', SUM(CAST(offlineTable.length AS UNSIGNED)) AS 'offlineSum', MAX(offlineTable.dateline) AS 'lastStart'
+ FROM ".self::getBoundedTableQueryString('~offline-length', $lowerTimeBound, $upperTimeBound, $cutOff)." offlineTable
+ INNER JOIN machine ON offlineTable.machineuuid = machine.machineuuid
+ GROUP BY machine.machineuuid
+ ) t2
+ ON t1.uuid = t2.uuid");
+ return $res;
+ }
+
+ // Location Data: Name, ID (anonymized), Time Online, Median Time Online, Time Offline, Number of Sessions > 60Sec, Number of Sessions < 60Sec
+ public static function getLocationStatistics($cutOff, $lowerTimeBound = 0, $upperTimeBound = 24) {
+ $notassigned = Dictionary::translateFile('template-tags', 'lang_notassigned');
+ $res = Database::simpleQuery("SELECT t1.locName AS locName, MD5(locId) AS locHash, timeSum, medianTime, offlineSum, longSessions, shortSessions FROM (
+ SELECT IFNULL(location.locationname, '$notassigned') AS 'locName', location.locationid AS 'locId', SUM(CAST(sessionTable.length AS UNSIGNED)) AS 'timeSum', GROUP_CONCAT(sessionTable.length) AS 'medianTime', SUM(sessionTable.length >= 60) AS 'longSessions', SUM(sessionTable.length < 60) AS 'shortSessions'
+ FROM ".self::getBoundedTableQueryString('~session-length', $lowerTimeBound, $upperTimeBound, $cutOff)." sessionTable
+ INNER JOIN machine ON sessionTable.machineuuid = machine.machineuuid
+ LEFT JOIN location ON machine.locationid = location.locationid
+ GROUP BY location.locationname
+ ) t1
+ INNER JOIN (
+ SELECT IFNULL(location.locationname, '$notassigned') AS 'locName', SUM(CAST(offlineTable.length AS UNSIGNED)) AS 'offlineSum'
+ FROM ".self::getBoundedTableQueryString('~offline-length', $lowerTimeBound, $upperTimeBound, $cutOff)." offlineTable
+ INNER JOIN machine ON offlineTable.machineuuid = machine.machineuuid
+ LEFT JOIN location ON machine.locationid = location.locationid
+ GROUP BY location.locationname
+ ) t2
+ ON t1.locName = t2.locName");
+ return $res;
+ }
+
+ // User Data: Name, Name(anonymized), Number of Logins
+ public static function getUserStatistics($cutOff, $lowerTimeBound = 0, $upperTimeBound = 24) {
+ $res = Database::simpleQuery("SELECT username AS name, IF(username = 'anonymous', 'anonymous', md5(username)) AS userHash, COUNT(*) AS 'count'
+ FROM statistic
+ WHERE typeid='.vmchooser-session-name' AND dateline+data >= UNIX_TIMESTAMP(CURDATE() - INTERVAL $cutOff DAY)
+ AND ((FROM_UNIXTIME(dateline+data, '%H')*1 >= $lowerTimeBound) AND (FROM_UNIXTIME(dateline, '%H')*1 < $upperTimeBound))
+ GROUP BY username
+ ORDER BY 2 DESC");
+ return $res;
+ }
+
+ // Virtual Machine Data: Name, Number of Usages
+ public static function getVMStatistics($cutOff, $lowerTimeBound = 0, $upperTimeBound = 24) {
+ $res = Database::simpleQuery("SELECT data AS name, COUNT(*) AS 'count' FROM statistic WHERE typeid='.vmchooser-session-name' AND dateline+data >= UNIX_TIMESTAMP(CURDATE() - INTERVAL $cutOff DAY)
+ AND ((FROM_UNIXTIME(dateline+data, '%H')*1 >= $lowerTimeBound) AND (FROM_UNIXTIME(dateline, '%H')*1 < $upperTimeBound))
+ GROUP BY data
+ ORDER BY 2 DESC");
+ return $res;
+ }
+
+ //Total Data: Time Online, Median Time Online, Number of Sessions > 60Sec, Number of Sessions < 60Sec
+ public static function getOverallStatistics ($cutOff, $lowerTimeBound = 0, $upperTimeBound = 24) {
+ $res = Database::simpleQuery("SELECT SUM(CAST(sessionTable.length AS UNSIGNED)) AS sum, GROUP_CONCAT(sessionTable.length) AS median, SUM(sessionTable.length >= 60) AS longSessions, SUM(sessionTable.length < 60) AS shortSessions
+ FROM ".self::getBoundedTableQueryString('~session-length', $lowerTimeBound, $upperTimeBound, $cutOff)." sessionTable");
+ return $res;
+ }
+
+ // Total Data(2): Time Offline
+ public static function getTotalOfflineStatistics($cutOff, $lowerTimeBound = 0, $upperTimeBound = 24) {
+ $res = Database::simpleQuery("SELECT SUM(CAST(offlineTable.length AS UNSIGNED)) AS timeOff
+ FROM ".self::getBoundedTableQueryString('~offline-length', $lowerTimeBound, $upperTimeBound, $cutOff)." offlineTable");
+ return $res;
+ }
+
+ // query string which provides table with time-cutoff and time-bounds
+ private static function getBoundedTableQueryString($typeid, $lowerTimeBound, $upperTimeBound, $cutOff)
+ {
+ $lowerFormat = "'%y-%m-%d $lowerTimeBound:00:00'";
+ $upperFormat = "'%y-%m-%d ".($upperTimeBound-1).":59:59'";
+ $queryString = "
+ select
+
+ @startLower := UNIX_TIMESTAMP(FROM_UNIXTIME(dateline, $lowerFormat)),
+ @startUpper := UNIX_TIMESTAMP(FROM_UNIXTIME(dateline, $upperFormat)),
+ @endLower := UNIX_TIMESTAMP(FROM_UNIXTIME(dateline+data, $lowerFormat)),
+ @endUpper := UNIX_TIMESTAMP(FROM_UNIXTIME(dateline+data, $upperFormat)),
+
+ (CAST(data AS SIGNED)
+ - IF(
+ dateline > @startUpper,
+ UNIX_TIMESTAMP(FROM_UNIXTIME(dateline, $lowerFormat) + INTERVAL 1 DAY) - dateline,
+ IF(
+ dateline < @startLower,
+ @startLower - dateline,
+ 0
+ )
+ )
+ - IF(
+ dateline+data > @endUpper,
+ dateline+data - (@endUpper + 1),
+ IF(
+ dateline+data < @endLower,
+ dateline+data - (UNIX_TIMESTAMP(FROM_UNIXTIME(dateline+data, $upperFormat) - INTERVAL 1 DAY) + 1),
+ 0
+ )
+ )
+ - ( TO_DAYS(FROM_UNIXTIME(dateline+data, '%y-%m-%d')) - TO_DAYS(FROM_UNIXTIME(dateline, '%y-%m-%d'))
+ - 2
+ + IF(dateline <= @startUpper, 1, 0)
+ + IF(dateline+data >= @endLower, 1, 0)
+ ) * ((24 - ($upperTimeBound - $lowerTimeBound)) * 3600)
+
+ - IF(
+ @leftBound := IF(dateline <= @startUpper, @startUpper, UNIX_TIMESTAMP(FROM_UNIXTIME(dateline, $upperFormat) + INTERVAL 1 DAY))
+ < @rightBound := IF(dateline+data >= @endLower, @endLower, UNIX_TIMESTAMP(FROM_UNIXTIME(dateline+data, $lowerFormat) - INTERVAL 1 DAY)),
+ IF(
+ @timeDiff := (
+ (date_format(from_unixtime(@leftBound), '%H') -
+ date_format(convert_tz(from_unixtime(@leftBound), @@session.time_zone, '+00:00'), '%H') + 24) % 24
+ -
+ (date_format(from_unixtime(@rightBound), '%H') -
+ date_format(convert_tz(from_unixtime(@rightBound), @@session.time_zone, '+00:00'), '%H') + 24) % 24) = 1
+ AND ($lowerTimeBound >= 2 OR $upperTimeBound <= 2),
+ 3600,
+ IF(@timeDiff = -1 AND ($lowerTimeBound >= 3 OR $upperTimeBound <= 3), -3600, 0)
+ ),
+ 0
+ )
+
+ ) as 'length',
+ dateline,
+ data,
+ machineuuid
+
+ from statistic
+ where dateline+data >= UNIX_TIMESTAMP(CURDATE() - INTERVAL $cutOff DAY) and typeid = '$typeid'
+ and (
+ (UNIX_TIMESTAMP(FROM_UNIXTIME(dateline, $lowerFormat)) <= dateline and dateline <= UNIX_TIMESTAMP(FROM_UNIXTIME(dateline, $upperFormat)))
+ or
+ (UNIX_TIMESTAMP(FROM_UNIXTIME(dateline+data, $lowerFormat)) <= dateline+data and dateline+data <= UNIX_TIMESTAMP(FROM_UNIXTIME(dateline+data, $upperFormat)))
+ )
+ ";
+ return "(".$queryString.")";
+ }
+}
+