true, 'visible' => true, 'filterControl' => 'input', ], $definition ); } return $columns; } private static function executeQuery(string $sql, array $params, array $columnsDefinition): PromiseInterface { return \XBotControl\Storage::getInstance()->db->query($sql, $params)->then(function ($result) use ($columnsDefinition) { return [ "columns" => $columnsDefinition, "rows" => $result->rows, ]; }); } private static function parseQueryParams(ServerRequestInterface $request): array { $query = $request->getQueryParams(); return [ 'from' => strtotime($query['from'] ?? 'yesterday'), 'to' => strtotime($query['to'] ?? 'now'), 'limit' => (int)($query['limit'] ?? 100), 'filter' => isset($query['filter']) ? json_decode($query['filter'], true) : [] ]; } private static function prepareFilterClauses(array $filter): array { $sql = ''; $params = []; foreach ($filter as $field => $value) { $sql .= 'AND ' . $field . ' LIKE ? '; $params[] = '%' . $value . '%'; } return [$sql, $params]; } public static function latest_requests(ServerRequestInterface $request): PromiseInterface { $columnsDefinition = self::generateColumns([ ["title" => "id", "field" => "id", "visible" => false], ["title" => "ip", "field" => "ip", 'formatter'=> 'ipFormatter'], ["title" => "domain", "field" => "domain", "visible" => false], ["title" => "path", "field" => "path"], ["title" => "useragent", "field" => "useragent"], ["title" => "load", "field" => "load"], ["title" => "datetime", "field" => "datetime"], ]); $queryParams = self::parseQueryParams($request); $sql = " SELECT req.rowid AS id, ip.data AS ip, domain.data AS domain, path.data AS path, useragent.data AS useragent, headers.data AS headers, (SELECT load.load1 FROM load WHERE load.rowid >= req.timestamp ORDER BY load.rowid DESC LIMIT 1) AS load, datetime(req.timestamp, 'auto') AS datetime FROM request req LEFT JOIN ip ON req.id_ip = ip.rowid LEFT JOIN domain ON req.id_domain = domain.rowid LEFT JOIN path ON req.id_path = path.rowid LEFT JOIN useragent ON req.id_useragent = useragent.rowid LEFT JOIN headers ON req.id_headers = headers.rowid WHERE 1=1 "; list($filterSQL, $filterParams) = self::prepareFilterClauses($queryParams['filter']); $sql .= $filterSQL . " AND req.timestamp BETWEEN ? AND ? ORDER BY req.rowid DESC LIMIT ?;"; $params = array_merge($filterParams, [$queryParams['from'], $queryParams['to'], $queryParams['limit']]); return self::executeQuery($sql, $params, $columnsDefinition); } public static function count_requests_by_ip(ServerRequestInterface $request): PromiseInterface { $columnsDefinition = self::generateColumns([ ["title" => "ip", "field" => "ip_address", 'formatter'=> 'ipFormatter'], ["title" => "request_count", "field" => "request_count"], ]); $queryParams = self::parseQueryParams($request); $sql = " SELECT ip.data AS ip_address, COUNT(request.id_ip) AS request_count FROM request INNER JOIN ip ON request.id_ip = ip.rowid WHERE request.timestamp BETWEEN ? AND ? GROUP BY ip.data ORDER BY request_count DESC LIMIT ?; "; $params = [$queryParams['from'], $queryParams['to'], $queryParams['limit']]; return self::executeQuery($sql, $params, $columnsDefinition); } public static function count_requests_by_ua(ServerRequestInterface $request): PromiseInterface { $columnsDefinition = self::generateColumns([ ["title" => "useragent", "field" => "id_useragent"], ["title" => "request_count", "field" => "request_count"], ]); $queryParams = self::parseQueryParams($request); $sql = " SELECT useragent.data AS id_useragent, COUNT(request.id_useragent) AS request_count FROM request INNER JOIN useragent ON request.id_useragent = useragent.rowid WHERE request.timestamp BETWEEN ? AND ? GROUP BY useragent.data ORDER BY request_count DESC LIMIT ?; "; $params = [$queryParams['from'], $queryParams['to'], $queryParams['limit']]; return self::executeQuery($sql, $params, $columnsDefinition); } public static function top_ip_ua_path(ServerRequestInterface $request): PromiseInterface { $columnsDefinition = self::generateColumns([ ["title" => "ip", "field" => "ip", 'formatter'=> 'ipFormatter'], ["title" => "useragent", "field" => "user_agent"], ["title" => "path", "field" => "path"], ["title" => "count", "field" => "count"], ]); $queryParams = self::parseQueryParams($request); $sql = " SELECT ip.data AS ip, useragent.data AS user_agent, path.data AS path, COUNT(request.rowid) AS count FROM request JOIN ip ON request.id_ip = ip.rowid JOIN useragent ON request.id_useragent = useragent.rowid JOIN path ON request.id_path = path.rowid WHERE request.timestamp BETWEEN ? AND ? GROUP BY ip.data, useragent.data, path.data ORDER BY count DESC LIMIT ?; "; $params = [$queryParams['from'], $queryParams['to'], $queryParams['limit']]; return self::executeQuery($sql, $params, $columnsDefinition); } public static function top_ip_by_load(ServerRequestInterface $request): PromiseInterface { $columnsDefinition = self::generateColumns([ ["title" => "ip", "field" => "data", 'formatter'=> 'ipFormatter'], ["title" => "avg_load", "field" => "avg_load"], ["title" => "request_count", "field" => "request_count"], ]); $queryParams = self::parseQueryParams($request); $sql = " SELECT ip.data, COUNT(request.rowid) AS request_count, AVG(load.load1) AS avg_load FROM request JOIN ip ON request.id_ip = ip.rowid JOIN load ON load.rowid = ( SELECT MIN(load_sub.rowid) FROM load AS load_sub WHERE load_sub.rowid > request.timestamp ) WHERE load.load1 > 1 AND request.timestamp BETWEEN ? AND ? GROUP BY ip.data ORDER BY avg_load DESC, request_count DESC LIMIT ?; "; $params = [$queryParams['from'], $queryParams['to'], $queryParams['limit']]; return self::executeQuery($sql, $params, $columnsDefinition); } public static function top_ip_by_rps(ServerRequestInterface $request): PromiseInterface { $columnsDefinition = self::generateColumns([ ["title" => "ip", "field" => "ip_address", 'formatter'=> 'ipFormatter'], ["title" => "avg_request_per_second", "field" => "avg_request_per_second"], ]); $queryParams = self::parseQueryParams($request); $sql = " WITH TimestampIPRequests AS ( SELECT id_ip, timestamp, COUNT(*) AS request_count FROM request WHERE request.timestamp BETWEEN ? AND ? GROUP BY id_ip, timestamp HAVING COUNT(*) > 1 ), IPRequestPerSecond AS ( SELECT id_ip, AVG(request_count) AS avg_request_per_second FROM TimestampIPRequests GROUP BY id_ip ) SELECT ip.data as ip_address, avg_request_per_second FROM IPRequestPerSecond JOIN ip ON IPRequestPerSecond.id_ip = ip.rowid ORDER BY avg_request_per_second DESC LIMIT ?; "; $params = [$queryParams['from'], $queryParams['to'], $queryParams['limit']]; return self::executeQuery($sql, $params, $columnsDefinition); } public static function top_net_28_by_rps(ServerRequestInterface $request): PromiseInterface { $columnsDefinition = self::generateColumns([ ["title" => "ip", "field" => "network"], ["title" => "avg_request_per_second", "field" => "avg_request_per_second"], ]); $queryParams = self::parseQueryParams($request); $sql = " CREATE FUNCTION cidr_to_network(cidr VARCHAR(30), prefix INT) RETURNS VARCHAR(30) BEGIN RETURN inet_ntoa(inet_aton(substring_index(cidr, '/', 1)) & ((2 ^ (32 - prefix)) - 1 ^ 0xFFFFFFFF)) || '/' || prefix; END; WITH TimestampNetworkRequests AS ( SELECT CAST(cidr_to_network(ip.data, 28) AS TEXT) AS network, timestamp, COUNT(*) AS request_count FROM request JOIN ip ON request.id_ip = ip.rowid WHERE request.timestamp BETWEEN ? AND ? GROUP BY network, timestamp HAVING COUNT(*) > 1 ), NetworkRequestPerSecond AS ( SELECT network, AVG(request_count) AS avg_request_per_second FROM TimestampNetworkRequests GROUP BY network ) SELECT network AS network_address, avg_request_per_second FROM NetworkRequestPerSecond ORDER BY avg_request_per_second DESC LIMIT ?; "; $params = [$queryParams['from'], $queryParams['to'], $queryParams['limit']]; return self::executeQuery($sql, $params, $columnsDefinition); } }