1<?php 2 3namespace dokuwiki\plugin\statistics; 4 5use dokuwiki\Logger; 6use dokuwiki\plugin\sqlite\SQLiteDB; 7use helper_plugin_statistics; 8 9/** 10 * This class defines a bunch of SQL queries to fetch various statistics from the database 11 */ 12class Query 13{ 14 protected helper_plugin_statistics $hlp; 15 protected SQLiteDB $db; 16 protected string $from; 17 protected string $to; 18 protected string $limit = ''; 19 protected string $tz = 'localtime'; 20 21 /** 22 * @param helper_plugin_statistics $hlp 23 */ 24 public function __construct(helper_plugin_statistics $hlp) 25 { 26 $this->hlp = $hlp; 27 $this->db = $hlp->getDB(); 28 $today = date('Y-m-d'); 29 $this->setTimeFrame($today, $today); 30 $this->setPagination(0, 20); 31 } 32 33 /** 34 * Set the time frame for all queries 35 * 36 * @param string $from The start date as YYYY-MM-DD 37 * @param string $to The end date as YYYY-MM-DD 38 */ 39 public function setTimeFrame(string $from, string $to): void 40 { 41 try { 42 $from = new \DateTime($from); 43 $to = new \DateTime($to); 44 } catch (\Exception $e) { 45 $from = new \DateTime(); 46 $to = new \DateTime(); 47 } 48 $from->setTime(0, 0); 49 $to->setTime(23, 59, 59); 50 51 $this->from = $from->format('Y-m-d H:i:s'); 52 $this->to = $to->format('Y-m-d H:i:s'); 53 54 $this->setTimezone(); 55 } 56 57 /** 58 * Force configured timezone. 59 * This is useful if you cannot set localtime on the server. 60 * 61 * @return void 62 */ 63 public function setTimezone() 64 { 65 $timezoneId = $this->hlp->getConf('timezone'); 66 if (!$timezoneId || !in_array($timezoneId, \DateTimeZone::listIdentifiers())) return; 67 68 try { 69 $dateTime = new \DateTime($this->from, new \DateTimeZone($timezoneId)); 70 $this->tz = $dateTime->format('P'); 71 } catch (\Exception $e) { 72 Logger::error($e->getMessage()); 73 } 74 } 75 76 /** 77 * Set the pagination settings for some queries 78 * 79 * @param int $start The start offset 80 * @param int $limit The number of results. If one more is returned, there is another page 81 * @return void 82 */ 83 public function setPagination(int $start, int $limit) 84 { 85 // when a limit is set, one more is fetched to indicate when a next page exists 86 if ($limit) $limit += 1; 87 88 if ($limit) { 89 $this->limit = " LIMIT $start,$limit"; 90 } elseif ($start) { 91 $this->limit = " OFFSET $start"; 92 } 93 } 94 95 /** 96 * Return some aggregated statistics 97 */ 98 public function aggregate(): array 99 { 100 // init some values that might not be set 101 $data = [ 102 'referers' => 0, // total number of (external) referrers 103 'external' => 0, // external referrers 104 'search' => 0, // search engine referrers 105 'direct' => 0, // direct referrers 106 'internal' => 0, // internal referrers 107 'bouncerate' => 0, 108 'newvisitors' => 0, 109 ]; 110 111 // Count referrer types by joining with referers table 112 $sql = "SELECT 113 CASE 114 WHEN R.engine IS NOT NULL THEN 'search' 115 WHEN R.url = '' THEN 'direct' 116 WHEN R.url IS NOT NULL THEN 'external' 117 ELSE 'internal' 118 END as ref_type, 119 COUNT(*) as cnt 120 FROM pageviews as P 121 LEFT JOIN referers as R ON P.ref_id = R.id 122 LEFT JOIN sessions as S ON P.session = S.session 123 WHERE DATETIME(P.dt, ?) >= ? AND DATETIME(P.dt, ?) <= ? 124 AND S.ua_type = 'browser' 125 GROUP BY ref_type"; 126 $result = $this->db->queryAll($sql, [$this->tz, $this->from, $this->tz, $this->to]); 127 128 foreach ($result as $row) { 129 if ($row['ref_type'] == 'search') { 130 $data['search'] = $row['cnt']; 131 $data['referers'] += $row['cnt']; 132 } 133 if ($row['ref_type'] == 'direct') { 134 $data['direct'] = $row['cnt']; 135 $data['referers'] += $row['cnt']; 136 } 137 if ($row['ref_type'] == 'external') { 138 $data['external'] = $row['cnt']; 139 $data['referers'] += $row['cnt']; 140 } 141 if ($row['ref_type'] == 'internal') { 142 $data['internal'] = $row['cnt']; 143 } 144 } 145 146 // general user and session info 147 $sql = "SELECT COUNT(DISTINCT P.session) as sessions, 148 COUNT(P.session) as views, 149 COUNT(DISTINCT S.user) as users, 150 COUNT(DISTINCT S.uid) as visitors, 151 DATETIME(MAX(P.dt), ?) as last 152 FROM pageviews as P 153 LEFT JOIN sessions as S ON P.session = S.session 154 WHERE DATETIME(P.dt, ?) >= ? AND DATETIME(P.dt, ?) <= ? 155 AND S.ua_type = 'browser'"; 156 $result = $this->db->queryRecord($sql, [$this->tz, $this->tz, $this->from, $this->tz, $this->to]); 157 158 $data['users'] = $result['users']; 159 $data['sessions'] = $result['sessions']; 160 $data['pageviews'] = $result['views']; 161 $data['visitors'] = $result['visitors']; 162 $data['last'] = $result['last']; 163 164 // calculate bounce rate (sessions with only 1 page view) 165 if ($data['sessions']) { 166 $sql = "SELECT COUNT(*) as cnt 167 FROM ( 168 SELECT P.session, COUNT(*) as views 169 FROM pageviews as P 170 LEFT JOIN sessions as S ON P.session = S.session 171 WHERE DATETIME(P.dt, ?) >= ? AND DATETIME(P.dt, ?) <= ? 172 AND S.ua_type = 'browser' 173 GROUP BY P.session 174 HAVING views = 1 175 )"; 176 $count = $this->db->queryValue($sql, [$this->tz, $this->from, $this->tz, $this->to]); 177 $data['bouncerate'] = $count * 100 / $data['sessions']; 178 $data['newvisitors'] = $count * 100 / $data['sessions']; 179 } 180 181 // calculate avg. number of views per session 182 $sql = "SELECT AVG(views) as cnt 183 FROM ( 184 SELECT P.session, COUNT(*) as views 185 FROM pageviews as P 186 LEFT JOIN sessions as S ON P.session = S.session 187 WHERE DATETIME(P.dt, ?) >= ? AND DATETIME(P.dt, ?) <= ? 188 AND S.ua_type = 'browser' 189 GROUP BY P.session 190 )"; 191 $data['avgpages'] = $this->db->queryValue($sql, [$this->tz, $this->from, $this->tz, $this->to]); 192 193 // average time spent on the site 194 $sql = "SELECT AVG((unixepoch(end) - unixepoch(dt)) / 60) as time 195 FROM sessions as S 196 WHERE S.dt != S.end 197 AND DATETIME(S.dt, ?) >= ? AND DATETIME(S.dt, ?) <= ? 198 AND S.ua_type = 'browser'"; 199 $data['timespent'] = $this->db->queryValue($sql, [$this->tz, $this->from, $this->tz, $this->to]); 200 201 // logins 202 $sql = "SELECT COUNT(*) as logins 203 FROM logins as A 204 WHERE DATETIME(A.dt, ?) >= ? AND DATETIME(A.dt, ?) <= ? 205 AND (type = 'l' OR type = 'p')"; 206 $data['logins'] = $this->db->queryValue($sql, [$this->tz, $this->from, $this->tz, $this->to]); 207 208 // registrations 209 $sql = "SELECT COUNT(*) as registrations 210 FROM logins as A 211 WHERE DATETIME(A.dt, ?) >= ? AND DATETIME(A.dt, ?) <= ? 212 AND type = 'C'"; 213 $data['registrations'] = $this->db->queryValue($sql, [$this->tz, $this->from, $this->tz, $this->to]); 214 215 // current users (based on recent sessions) 216 $sql = "SELECT COUNT(DISTINCT uid) as current 217 FROM sessions 218 WHERE end >= datetime('now', '-10 minutes')"; 219 $data['current'] = $this->db->queryValue($sql); 220 221 return $data; 222 } 223 224 225 /** 226 * Return some trend data about visits and edits in the wiki 227 * 228 * @param bool $hours Use hour resolution rather than days 229 * @return array 230 */ 231 public function dashboardviews(bool $hours = false): array 232 { 233 if ($hours) { 234 $TIME = "strftime('%H', DATETIME(P.dt, '$this->tz'))"; 235 } else { 236 $TIME = "DATE(DATETIME(P.dt, '$this->tz'))"; 237 } 238 239 $data = []; 240 241 // access trends 242 $sql = "SELECT $TIME as time, 243 COUNT(DISTINCT P.session) as sessions, 244 COUNT(P.session) as pageviews, 245 COUNT(DISTINCT S.uid) as visitors 246 FROM pageviews as P 247 LEFT JOIN sessions as S ON P.session = S.session 248 WHERE DATETIME(P.dt, ?) >= ? AND DATETIME(P.dt, ?) <= ? 249 AND S.ua_type = 'browser' 250 GROUP BY $TIME 251 ORDER BY time"; 252 $result = $this->db->queryAll($sql, [$this->tz, $this->from, $this->tz, $this->to]); 253 foreach ($result as $row) { 254 $data[$row['time']]['sessions'] = $row['sessions']; 255 $data[$row['time']]['pageviews'] = $row['pageviews']; 256 $data[$row['time']]['visitors'] = $row['visitors']; 257 } 258 return $data; 259 } 260 261 /** 262 * @param bool $hours Use hour resolution rather than days 263 * @return array 264 */ 265 public function dashboardwiki(bool $hours = false): array 266 { 267 if ($hours) { 268 $TIME = "strftime('%H', DATETIME(dt, '$this->tz'))"; 269 } else { 270 $TIME = "DATE(DATETIME(dt, '$this->tz'))"; 271 } 272 273 $data = []; 274 275 // edit trends 276 foreach (['E', 'C', 'D'] as $type) { 277 $sql = "SELECT $TIME as time, 278 COUNT(*) as cnt 279 FROM edits as A 280 WHERE DATETIME(A.dt, ?) >= ? AND DATETIME(A.dt, ?) <= ? 281 AND type = '$type' 282 GROUP BY $TIME 283 ORDER BY time"; 284 $result = $this->db->queryAll($sql, [$this->tz, $this->from, $this->tz, $this->to]); 285 foreach ($result as $row) { 286 $data[$row['time']][$type] = $row['cnt']; 287 } 288 } 289 ksort($data); 290 return $data; 291 } 292 293 /** 294 * @param string $info Which type of history to select (FIXME which ones are there?) 295 * @param string $interval Group data by this interval (days, weeks, months) 296 * @return array 297 */ 298 public function history(string $info, string $interval = 'day'): array 299 { 300 if ($interval == 'weeks') { 301 $TIME = "strftime('%Y', DATETIME(dt, '$this->tz')), strftime('%W', DATETIME(dt, '$this->tz'))"; 302 } elseif ($interval == 'months') { 303 $TIME = "strftime('%Y-%m', DATETIME(dt, '$this->tz'))"; 304 } else { 305 $TIME = "strftime('%d-%m', DATETIME(dt, '$this->tz'))"; 306 } 307 308 $mod = 1; 309 if ($info == 'media_size' || $info == 'page_size') { 310 $mod = 1024 * 1024; 311 } 312 313 $sql = "SELECT $TIME as time, 314 AVG(value)/$mod as cnt 315 FROM history as A 316 WHERE DATETIME(A.dt, ?) >= ? AND DATETIME(A.dt, ?) <= ? 317 AND info = ? 318 GROUP BY $TIME 319 ORDER BY $TIME"; 320 321 return $this->db->queryAll($sql, [$this->tz, $this->from, $this->tz, $this->to, $info]); 322 } 323 324 /** 325 * @return array 326 */ 327 public function searchengines(): array 328 { 329 $sql = "SELECT COUNT(*) as cnt, R.engine 330 FROM pageviews as P, 331 referers as R 332 WHERE DATETIME(P.dt, ?) >= ? AND DATETIME(P.dt, ?) <= ? 333 AND P.ref_id = R.id 334 AND R.engine != '' 335 GROUP BY R.engine 336 ORDER BY cnt DESC, R.engine" . 337 $this->limit; 338 return $this->db->queryAll($sql, [$this->tz, $this->from, $this->tz, $this->to]); 339 } 340 341 /** 342 * @return array 343 */ 344 public function internalsearchphrases(): array 345 { 346 $sql = "SELECT COUNT(*) as cnt, query, query as ilookup 347 FROM search 348 WHERE DATETIME(dt, ?) >= ? AND DATETIME(dt, ?) <= ? 349 GROUP BY query 350 ORDER BY cnt DESC, query" . 351 $this->limit; 352 return $this->db->queryAll($sql, [$this->tz, $this->from, $this->tz, $this->to]); 353 } 354 355 /** 356 * @return array 357 */ 358 public function internalsearchwords(): array 359 { 360 $sql = "SELECT COUNT(*) as cnt, SW.word, SW.word as ilookup 361 FROM search as S, 362 searchwords as SW 363 WHERE DATETIME(S.dt, ?) >= ? AND DATETIME(S.dt, ?) <= ? 364 AND S.id = SW.sid 365 GROUP BY SW.word 366 ORDER BY cnt DESC, SW.word" . 367 $this->limit; 368 return $this->db->queryAll($sql, [$this->tz, $this->from, $this->tz, $this->to]); 369 } 370 371 /** 372 * @return array 373 */ 374 public function outlinks(): array 375 { 376 $sql = "SELECT COUNT(*) as cnt, link as url 377 FROM outlinks as A 378 WHERE DATETIME(A.dt, ?) >= ? AND DATETIME(A.dt, ?) <= ? 379 GROUP BY link 380 ORDER BY cnt DESC, link" . 381 $this->limit; 382 return $this->db->queryAll($sql, [$this->tz, $this->from, $this->tz, $this->to]); 383 } 384 385 /** 386 * @return array 387 */ 388 public function pages(): array 389 { 390 $sql = "SELECT COUNT(*) as cnt, P.page 391 FROM pageviews as P, 392 sessions as S 393 WHERE DATETIME(P.dt, ?) >= ? AND DATETIME(P.dt, ?) <= ? 394 AND P.session = S.session 395 AND S.ua_type = 'browser' 396 GROUP BY P.page 397 ORDER BY cnt DESC, P.page" . 398 $this->limit; 399 return $this->db->queryAll($sql, [$this->tz, $this->from, $this->tz, $this->to]); 400 } 401 402 /** 403 * @return array 404 */ 405 public function edits(): array 406 { 407 $sql = "SELECT COUNT(*) as cnt, page 408 FROM edits as A 409 WHERE DATETIME(A.dt, ?) >= ? AND DATETIME(A.dt, ?) <= ? 410 GROUP BY page 411 ORDER BY cnt DESC, page" . 412 $this->limit; 413 return $this->db->queryAll($sql, [$this->tz, $this->from, $this->tz, $this->to]); 414 } 415 416 /** 417 * @return array 418 */ 419 public function images(): array 420 { 421 $sql = "SELECT COUNT(*) as cnt, media, SUM(size) as filesize 422 FROM media as A 423 WHERE DATETIME(A.dt, ?) >= ? AND DATETIME(A.dt, ?) <= ? 424 AND mime1 = 'image' 425 GROUP BY media 426 ORDER BY cnt DESC, media" . 427 $this->limit; 428 return $this->db->queryAll($sql, [$this->tz, $this->from, $this->tz, $this->to]); 429 } 430 431 /** 432 * @return array 433 */ 434 public function imagessum(): array 435 { 436 $sql = "SELECT COUNT(*) as cnt, SUM(size) as filesize 437 FROM media as A 438 WHERE DATETIME(A.dt, ?) >= ? AND DATETIME(A.dt, ?) <= ? 439 AND mime1 = 'image'"; 440 return $this->db->queryAll($sql, [$this->tz, $this->from, $this->tz, $this->to]); 441 } 442 443 /** 444 * @return array 445 */ 446 public function downloads(): array 447 { 448 $sql = "SELECT COUNT(*) as cnt, media, SUM(size) as filesize 449 FROM media as A 450 WHERE DATETIME(A.dt, ?) >= ? AND DATETIME(A.dt, ?) <= ? 451 AND mime1 != 'image' 452 GROUP BY media 453 ORDER BY cnt DESC, media" . 454 $this->limit; 455 return $this->db->queryAll($sql, [$this->tz, $this->from, $this->tz, $this->to]); 456 } 457 458 /** 459 * @return array 460 */ 461 public function downloadssum(): array 462 { 463 $sql = "SELECT COUNT(*) as cnt, SUM(size) as filesize 464 FROM media as A 465 WHERE DATETIME(A.dt, ?) >= ? AND DATETIME(A.dt, ?) <= ? 466 AND mime1 != 'image'"; 467 return $this->db->queryAll($sql, [$this->tz, $this->from, $this->tz, $this->to]); 468 } 469 470 /** 471 * @return array 472 */ 473 public function referer(): array 474 { 475 $sql = "SELECT COUNT(*) as cnt, R.url 476 FROM pageviews as P 477 LEFT JOIN sessions as S ON P.session = S.session 478 LEFT JOIN referers as R ON P.ref_id = R.id 479 WHERE DATETIME(P.dt, ?) >= ? AND DATETIME(P.dt, ?) <= ? 480 AND S.ua_type = 'browser' 481 AND R.url IS NOT NULL 482 AND R.url != '' 483 AND R.engine IS NULL 484 GROUP BY R.url 485 ORDER BY cnt DESC, R.url" . 486 $this->limit; 487 return $this->db->queryAll($sql, [$this->tz, $this->from, $this->tz, $this->to]); 488 } 489 490 /** 491 * @return array 492 */ 493 public function newreferer(): array 494 { 495 $sql = "SELECT COUNT(*) as cnt, R.url 496 FROM pageviews as P 497 LEFT JOIN sessions as S ON P.session = S.session 498 LEFT JOIN referers as R ON P.ref_id = R.id 499 WHERE DATETIME(P.dt, ?) >= ? AND DATETIME(P.dt, ?) <= ? 500 AND S.ua_type = 'browser' 501 AND R.url IS NOT NULL 502 AND R.url != '' 503 AND R.engine IS NULL 504 AND DATETIME(R.dt, ?) >= ? 505 GROUP BY R.url 506 ORDER BY cnt DESC, R.url" . 507 $this->limit; 508 return $this->db->queryAll($sql, [$this->tz, $this->from, $this->tz, $this->to, $this->tz, $this->from]); 509 } 510 511 /** 512 * @return array 513 */ 514 public function campaigns(): array 515 { 516 $sql = "SELECT COUNT(*) as cnt, C.campaign 517 FROM campaigns as C, 518 sessions as S 519 WHERE DATETIME(S.dt, ?) >= ? AND DATETIME(S.dt, ?) <= ? 520 AND S.session = C.session 521 GROUP BY C.campaign 522 ORDER BY cnt DESC, C.campaign" . 523 $this->limit; 524 return $this->db->queryAll($sql, [$this->tz, $this->from, $this->tz, $this->to]); 525 } 526 527 /** 528 * @return array 529 */ 530 public function source(): array 531 { 532 $sql = "SELECT COUNT(*) as cnt, C.campaign || ' ' || C.source AS campaign 533 FROM campaigns as C, 534 sessions as S 535 WHERE DATETIME(S.dt, ?) >= ? AND DATETIME(S.dt, ?) <= ? 536 AND S.session = C.session 537 AND C.source IS NOT NULL 538 GROUP BY C.campaign, C.source 539 ORDER BY cnt DESC, C.campaign" . 540 $this->limit; 541 return $this->db->queryAll($sql, [$this->tz, $this->from, $this->tz, $this->to]); 542 } 543 544 /** 545 * @return array 546 */ 547 public function medium(): array 548 { 549 $sql = "SELECT COUNT(*) as cnt, C.campaign || ' ' || C.medium AS campaign 550 FROM campaigns as C, 551 sessions as S 552 WHERE DATETIME(S.dt, ?) >= ? AND DATETIME(S.dt, ?) <= ? 553 AND S.session = C.session 554 AND C.medium IS NOT NULL 555 GROUP BY C.campaign, C.medium 556 ORDER BY cnt DESC, C.campaign" . 557 $this->limit; 558 return $this->db->queryAll($sql, [$this->tz, $this->from, $this->tz, $this->to]); 559 } 560 561 562 /** 563 * @return array 564 */ 565 public function countries(): array 566 { 567 $sql = "SELECT COUNT(DISTINCT P.session) as cnt, I.country 568 FROM pageviews as P, 569 iplocation as I 570 WHERE DATETIME(P.dt, ?) >= ? AND DATETIME(P.dt, ?) <= ? 571 AND P.ip = I.ip 572 AND I.country != '' 573 GROUP BY I.code 574 ORDER BY cnt DESC, I.country" . 575 $this->limit; 576 return $this->db->queryAll($sql, [$this->tz, $this->from, $this->tz, $this->to]); 577 } 578 579 /** 580 * @param bool $ext return extended information 581 * @return array 582 */ 583 public function browsers(bool $ext = false): array 584 { 585 if ($ext) { 586 $sel = 'S.ua_info as browser, S.ua_ver'; 587 $grp = 'S.ua_info, S.ua_ver'; 588 } else { 589 $sel = 'S.ua_info as browser'; 590 $grp = 'S.ua_info'; 591 } 592 593 $sql = "SELECT COUNT(DISTINCT S.session) as cnt, $sel 594 FROM sessions as S 595 WHERE DATETIME(S.dt, ?) >= ? AND DATETIME(S.dt, ?) <= ? 596 AND S.ua_type = 'browser' 597 GROUP BY $grp 598 ORDER BY cnt DESC, S.ua_info" . 599 $this->limit; 600 return $this->db->queryAll($sql, [$this->tz, $this->from, $this->tz, $this->to]); 601 } 602 603 /** 604 * @return array 605 */ 606 public function os(): array 607 { 608 $sql = "SELECT COUNT(DISTINCT S.session) as cnt, S.os 609 FROM sessions as S 610 WHERE DATETIME(S.dt, ?) >= ? AND DATETIME(S.dt, ?) <= ? 611 AND S.ua_type = 'browser' 612 GROUP BY S.os 613 ORDER BY cnt DESC, S.os" . 614 $this->limit; 615 return $this->db->queryAll($sql, [$this->tz, $this->from, $this->tz, $this->to]); 616 } 617 618 /** 619 * @return array 620 */ 621 public function topdomain(): array 622 { 623 $sql = "SELECT COUNT(*) as cnt, U.domain 624 FROM pageviews as P, 625 sessions as S, 626 users as U 627 WHERE DATETIME(P.dt, ?) >= ? AND DATETIME(P.dt, ?) <= ? 628 AND P.session = S.session 629 AND S.user = U.user 630 AND S.ua_type = 'browser' 631 AND S.user IS NOT NULL 632 GROUP BY U.domain 633 ORDER BY cnt DESC, U.domain" . 634 $this->limit; 635 return $this->db->queryAll($sql, [$this->tz, $this->from, $this->tz, $this->to]); 636 } 637 638 /** 639 * @return array 640 */ 641 public function topuser(): array 642 { 643 $sql = "SELECT COUNT(*) as cnt, S.user 644 FROM pageviews as P, 645 sessions as S 646 WHERE DATETIME(P.dt, ?) >= ? AND DATETIME(P.dt, ?) <= ? 647 AND P.session = S.session 648 AND S.ua_type = 'browser' 649 AND S.user IS NOT NULL 650 GROUP BY S.user 651 ORDER BY cnt DESC, S.user" . 652 $this->limit; 653 return $this->db->queryAll($sql, [$this->tz, $this->from, $this->tz, $this->to]); 654 } 655 656 /** 657 * @return array 658 */ 659 public function topeditor(): array 660 { 661 $sql = "SELECT COUNT(*) as cnt, user 662 FROM edits as E, 663 sessions as S 664 WHERE DATETIME(E.dt, ?) >= ? AND DATETIME(E.dt, ?) <= ? 665 AND E.session = S.session 666 AND S.user IS NOT NULL 667 GROUP BY user 668 ORDER BY cnt DESC, user" . 669 $this->limit; 670 return $this->db->queryAll($sql, [$this->tz, $this->from, $this->tz, $this->to]); 671 } 672 673 /** 674 * @return array 675 */ 676 public function topgroup(): array 677 { 678 $sql = "SELECT COUNT(*) as cnt, G.`group` 679 FROM pageviews as P, 680 sessions as S, 681 groups as G 682 WHERE DATETIME(P.dt, ?) >= ? AND DATETIME(P.dt, ?) <= ? 683 AND P.session = S.session 684 AND S.user = G.user 685 AND S.ua_type = 'browser' 686 GROUP BY G.`group` 687 ORDER BY cnt DESC, G.`group`" . 688 $this->limit; 689 return $this->db->queryAll($sql, [$this->tz, $this->from, $this->tz, $this->to]); 690 } 691 692 /** 693 * @return array 694 */ 695 public function topgroupedit(): array 696 { 697 $sql = "SELECT COUNT(*) as cnt, G.`group` 698 FROM edits as E, 699 sessions as S, 700 groups as G 701 WHERE DATETIME(E.dt, ?) >= ? AND DATETIME(E.dt, ?) <= ? 702 AND E.session = S.session 703 AND S.user = G.user 704 GROUP BY G.`group` 705 ORDER BY cnt DESC, G.`group`" . 706 $this->limit; 707 return $this->db->queryAll($sql, [$this->tz, $this->from, $this->tz, $this->to]); 708 } 709 710 711 /** 712 * @return array 713 */ 714 public function resolution(): array 715 { 716 $sql = "SELECT COUNT(DISTINCT S.uid) as cnt, 717 ROUND(P.screen_x/100)*100 as res_x, 718 ROUND(P.screen_y/100)*100 as res_y, 719 CAST(ROUND(P.screen_x/100)*100 AS int) 720 || 'x' || 721 CAST(ROUND(P.screen_y/100)*100 AS int) as resolution 722 FROM pageviews as P, 723 sessions as S 724 WHERE DATETIME(P.dt, ?) >= ? AND DATETIME(P.dt, ?) <= ? 725 AND P.session = S.session 726 AND S.ua_type = 'browser' 727 AND P.screen_x != 0 728 AND P.screen_y != 0 729 GROUP BY resolution 730 ORDER BY cnt DESC" . 731 $this->limit; 732 return $this->db->queryAll($sql, [$this->tz, $this->from, $this->tz, $this->to]); 733 } 734 735 /** 736 * @return array 737 */ 738 public function viewport(): array 739 { 740 $sql = "SELECT COUNT(DISTINCT S.uid) as cnt, 741 ROUND(P.view_x/100)*100 as res_x, 742 ROUND(P.view_y/100)*100 as res_y, 743 CAST(ROUND(P.view_x/100)*100 AS int) 744 || 'x' || 745 CAST(ROUND(P.view_y/100)*100 AS int) as resolution 746 FROM pageviews as P, 747 sessions as S 748 WHERE DATETIME(P.dt, ?) >= ? AND DATETIME(P.dt, ?) <= ? 749 AND P.session = S.session 750 AND S.ua_type = 'browser' 751 AND P.view_x != 0 752 AND P.view_y != 0 753 GROUP BY resolution 754 ORDER BY cnt DESC" . 755 $this->limit; 756 757 return $this->db->queryAll($sql, [$this->tz, $this->from, $this->tz, $this->to]); 758 } 759 760 /** 761 * @return array 762 */ 763 public function seenusers(): array 764 { 765 $sql = "SELECT `user`, MAX(`dt`) as dt 766 FROM users 767 WHERE `user` IS NOT NULL 768 AND `user` != '' 769 GROUP BY `user` 770 ORDER BY `dt` DESC" . 771 $this->limit; 772 773 return $this->db->queryAll($sql); 774 } 775} 776