Files
ops-Gazelle/app/Stats/Users.php

880 lines
34 KiB
PHP

<?php
namespace Gazelle\Stats;
use Gazelle\Enum\UserStatus;
class Users extends \Gazelle\Base {
protected const USER_BROWSER = 'stat_u2_browser';
protected const USER_CLASS = 'stat_u2_class';
protected const USER_GEODIST = 'stat_u_geodist';
protected const USER_PLATFORM = 'stat_u2_platform';
protected const FLOW = 'stat_u_flow';
protected array $info;
public function flush(): static {
self::$cache->deleteMulti([
self::USER_BROWSER,
self::USER_CLASS,
self::USER_GEODIST,
self::USER_PLATFORM,
self::FLOW,
]);
unset($this->info);
return $this;
}
public function flushTop(int $limit): static {
self::$cache->deleteMulti([
"topuserdl_$limit",
"topuserds_$limit",
"topuserul_$limit",
"topuserus_$limit",
"topusertotup_$limit",
]);
return $this;
}
/**
* The annual flow of users: people registered and disabled
*/
public function flow(): array {
$flow = self::$cache->get_value(self::FLOW);
if ($flow === false) {
self::$db->prepared_query("
WITH RECURSIVE dates AS (
SELECT last_day(now() - INTERVAL 24 MONTH) AS eom
UNION ALL
SELECT last_day(eom + INTERVAL 1 MONTH)
FROM dates
WHERE last_day(eom + INTERVAL 1 MONTH) < last_day(now())
),
unew AS (
SELECT count(*) AS total,
last_day(u.created) AS eom
FROM users_main u
WHERE last_day(u.created)
BETWEEN last_day(now() - INTERVAL 24 MONTH)
AND last_day(now() - INTERVAL 1 MONTH)
GROUP BY eom
)
SELECT date_format(dates.eom, '%Y-%m') AS Month,
coalesce(unew.total, 0) AS new,
count(distinct ui.UserID) AS disabled
FROM dates
LEFT JOIN unew USING (eom)
LEFT JOIN users_info ui ON (last_day(ui.BanDate) = dates.eom)
GROUP BY dates.eom
ORDER BY dates.eom
");
$flow = self::$db->to_array('Month', MYSQLI_ASSOC);
foreach ($flow as &$f) {
$f['new'] = (int)$f['new'];
}
unset($f);
self::$cache->cache_value(self::FLOW, $flow, mktime(0, 0, 0, date('n') + 1, 2)); //Tested: fine for Dec -> Jan
}
return $flow;
}
/**
* Reformat the output of a label, total query to simplify the consumption by highcharts
*/
protected function reformatDist(array $result): array {
$dist = [];
foreach ($result as $label => $total) {
$dist[] = [
'name' => $label,
'y' => $total,
];
}
return $dist;
}
/**
* Users aggregated by browser
*/
public function browserDistributionList(bool $viewAll): array {
$dist = self::$cache->get_value(self::USER_BROWSER);
if ($dist === false) {
self::$db->prepared_query("
SELECT coalesce(Browser, 'unreported') AS label,
count(*) AS total
FROM users_sessions
GROUP BY label
ORDER BY total DESC
");
$dist = self::$db->to_pair('label', 'total');
self::$cache->cache_value(self::USER_BROWSER, $dist, 86400);
}
$result = [];
// Users see up to the 10 most popular browsers with totals rounded up
// to the nearest 10. Staff see everything.
foreach ($dist as $label => $total) {
if ($viewAll) {
$result[$label] = $total;
} elseif ($label === 'staff-browser') {
continue;
} elseif ($total > 10) {
$result[$label] = (int)(ceil($total / 10) * 10);
if (count($result) >= 10) {
break;
}
}
}
return $result;
}
public function browserDistribution($viewAll): array {
return $this->reformatDist($this->browserDistributionList($viewAll));
}
/**
* Users aggregated by primary class
*/
public function userclassDistributionList(bool $viewAll): array {
$dist = self::$cache->get_value(self::USER_CLASS);
if ($dist === false) {
self::$db->prepared_query("
SELECT p.Name AS label,
p.Level AS level,
count(um.ID) AS total
FROM permissions p
LEFT JOIN users_main um ON (um.PermissionID = p.ID)
WHERE p.Secondary = 0
AND (um.ID IS NULL OR um.Enabled = ?)
GROUP BY p.Name, p.Level
ORDER BY p.Level
", UserStatus::enabled->value
);
$dist = self::$db->to_array(false, MYSQLI_ASSOC);
self::$cache->cache_value(self::USER_CLASS, $dist, 86400);
}
$result = [];
// Users only see non-staff userclasses (the staff classes can be
// worked out by consulting the Staff roster page in any event).
// Staff see all userclasses.
foreach ($dist as $d) {
if (
$viewAll
|| ($d['level'] >= CLASSLEVEL_USER && $d['level'] < CLASSLEVEL_STAFF)
) {
$result[$d['label']] = $d['total'];
}
}
return $result;
}
public function userclassDistribution(bool $viewAll): array {
return $this->reformatDist($this->userclassDistributionList($viewAll));
}
/**
* Users aggregated by OS platform
*/
public function platformDistributionList(bool $viewAll): array {
$dist = self::$cache->get_value(self::USER_PLATFORM);
if ($dist === false) {
self::$db->prepared_query("
SELECT coalesce(OperatingSystem, 'unreported') AS label,
count(*) AS total
FROM users_sessions
GROUP BY label
ORDER BY total DESC
");
$dist = self::$db->to_array(false, MYSQLI_ASSOC);
self::$cache->cache_value(self::USER_PLATFORM, $dist, 86400);
}
$result = [];
// Users see up to the 10 most popular platforms with totals rounded up
// to the nearest 10. Staff see everything.
foreach ($dist as $d) {
if ($viewAll) {
$result[$d['label']] = $d['total'];
} elseif ($d['total'] > 10) {
$result[$d['label']] = (int)(ceil($d['total'] / 10) * 10);
}
}
return $result;
}
public function platformDistribution(bool $viewAll): array {
return $this->reformatDist($this->platformDistributionList($viewAll));
}
/**
* Country aggregates. For privacy, countries with less than 20 members
* are rounded up to 20, then increases by increments of 10.
* Precise numbers are made available for consumption by staff.
* If the $iso array is supplied, it is assumed to be a lookup
* table for ISO31660-1 to country name.
*/
public function geodistribution(array $iso = []): array {
$info = self::$cache->get_value(self::USER_GEODIST);
if ($info === false) {
self::$db->prepared_query("
WITH geo AS (
SELECT ipcc,
count(*) AS total,
greatest(count(*), ?) AS rounded
FROM users_main
GROUP BY ipcc
ORDER BY total
)
SELECT geo.ipcc,
geo.total AS staff,
ceil(rounded / ?) * ? AS public,
ntile(100) OVER (ORDER BY rounded ASC) AS n
FROM geo
ORDER BY n DESC,
public DESC,
staff DESC,
ipcc
", COUNTRY_MINIMUM, COUNTRY_STEP, COUNTRY_STEP
);
$info = [];
foreach (self::$db->to_array(false, MYSQLI_ASSOC) as $row) {
$row['public'] = (int)$row['public']; // ceil() returns a float
$row['country'] = isset($iso[$row['ipcc']]) ? "{$iso[$row['ipcc']]} [{$row['ipcc']}]" : "[{$row['ipcc']}]";
$info[] = $row;
}
self::$cache->cache_value(self::USER_GEODIST, $info, 86400 * 2);
}
return $info;
}
public function geodistributionChart(\Gazelle\User $user): array {
return array_map(
fn ($c) => [
'ipcc' => $c['ipcc'],
'name' => $c['country'],
'value' => $user->isStaff() ? $c['staff'] : $c['public'],
],
$this->geodistribution(ISO3166_2()),
);
}
public function peerStat(): array {
if (!isset($this->info)) {
$this->info = [];
}
if (!isset($this->info['xbt_files_users'])) {
$stat = self::$cache->get_value('stat_xbt_fu');
if ($stat === false) {
$stat = array_map('intval',
self::$db->rowAssoc("
SELECT count(*) AS peer_total,
sum(if(remaining = 0, 1, 0)) AS seeder_total,
sum(if(remaining > 0, 1, 0)) AS leecher_total
FROM xbt_files_users
WHERE active = 1
") ?? ['seeder_total' => 0, 'leecher_total' => 0]
);
self::$cache->cache_value('stat_xbt_fu', $stat, 3600 + random_int(0, 120));
}
$this->info['xbt_files_users'] = $stat;
}
return $this->info['xbt_files_users'];
}
public function leecherTotal(): int {
return $this->peerStat()['leecher_total'];
}
public function peerTotal(): int {
return $this->peerStat()['peer_total'];
}
public function seederTotal(): int {
return $this->peerStat()['seeder_total'];
}
public function snatchTotal(): int {
if (!isset($this->info)) {
$this->info = [];
}
if (!isset($this->info['snatch'])) {
$total = self::$cache->get_value('stats_snatch');
if ($total === false) {
$total = (int)self::$db->scalar("SELECT count(*) FROM xbt_snatched");
self::$cache->cache_value('stats_snatch', $total, 3600 + random_int(0, 12));
}
$this->info['snatch'] = $total;
}
return $this->info['snatch'];
}
/**
* Get the number of enabled users.
*
* @return int Number of enabled users (this is cached).
*/
public function enabledUserTotal(): int {
if (!isset($this->info)) {
$this->info = [];
}
if (!isset($this->info['enabled'])) {
$total = self::$cache->get_value('stats_user_count');
if ($total === false) {
$total = (int)self::$db->scalar("
SELECT count(*) FROM users_main WHERE Enabled = ?
", UserStatus::enabled->value
);
self::$cache->cache_value('stats_user_count', $total, 7200);
}
$this->info['enabled'] = $total;
}
return $this->info['enabled'];
}
/**
* Can new members be invited at this time?
*/
public function newUsersAllowed(\Gazelle\User $user): bool {
return (
USER_LIMIT == 0
|| $this->enabledUserTotal() < USER_LIMIT
|| $user->permitted('site_can_invite_always')
);
}
public function activityStat(): array {
if (!isset($this->info)) {
$this->info = [];
}
if (!isset($this->info['active'])) {
$active = self::$cache->get_value('stats_user_active');
if ($active === false) {
$active = array_map('intval',
self::$db->rowAssoc("
SELECT
sum(ula.last_access > now() - INTERVAL 1 DAY) AS active_day,
sum(ula.last_access > now() - INTERVAL 1 WEEK) AS active_week,
sum(ula.last_access > now() - INTERVAL 1 MONTH) AS active_month
FROM users_main um
INNER JOIN user_last_access AS ula ON (ula.user_id = um.ID)
WHERE um.Enabled = ?
AND ula.last_access > now() - INTERVAL 1 MONTH
", UserStatus::enabled->value
)
?? ['active_day' => 0, 'active_week' => 0, 'active_month' => 0]
);
self::$cache->cache_value('stats_user_active', $active, 7200 + random_int(0, 300));
}
$this->info['active'] = $active;
}
return $this->info['active'];
}
public function dayActiveTotal(): int {
return $this->activityStat()['active_day'];
}
public function weekActiveTotal(): int {
return $this->activityStat()['active_week'];
}
public function monthActiveTotal(): int {
return $this->activityStat()['active_month'];
}
public function stockpileTokenList(int $limit): array {
self::$db->prepared_query("
SELECT user_id,
tokens AS total
FROM user_flt
ORDER BY tokens DESC
LIMIT ?
", $limit
);
return self::$db->to_array(false, MYSQLI_ASSOC);
}
public function refresh(): int {
self::$db->dropTemporaryTable("user_summary_new");
self::$db->prepared_query("
CREATE TEMPORARY TABLE user_summary_new LIKE user_summary
");
/* Need to perform dirty reads to avoid wedging users, especially inserts to users_downloads */
self::$db->prepared_query("
SET SESSION TRANSACTION ISOLATION LEVEL READ UNCOMMITTED
");
self::$db->prepared_query("
INSERT INTO user_summary_new (user_id, artist_added_total)
SELECT ta.UserID, count(*)
FROM torrents_artists ta
INNER JOIN users_main um ON (um.ID = ta.UserID)
GROUP BY ta.UserID
ON DUPLICATE KEY UPDATE
artist_added_total = VALUES(artist_added_total)
");
self::$db->prepared_query("
INSERT INTO user_summary_new (user_id, collage_total, collage_contrib)
WITH c AS (
SELECT c.UserID AS user_id,
count(c.ID) AS total
FROM collages c
WHERE c.Deleted = '0'
GROUP BY c.UserID
),
ca AS (
SELECT ca.UserID AS user_id,
count(DISTINCT ca.ArtistID) AS total
FROM collages_artists ca
INNER JOIN collages c ON (c.ID = ca.CollageID AND c.Deleted = '0')
GROUP BY ca.UserID
),
ct AS (
SELECT ct.UserID AS user_id,
count(DISTINCT ct.GroupID) AS total
FROM collages_torrents ct
INNER JOIN collages c ON (c.ID = ct.CollageID AND c.Deleted = '0')
GROUP BY ct.UserID
)
SELECT um.ID, coalesce(c.total, 0), coalesce(ca.total, 0) + coalesce(ct.total, 0)
FROM users_main um
LEFT JOIN c ON (c.user_id = um.ID)
LEFT JOIN ca ON (ca.user_id = um.ID)
LEFT JOIN ct ON (ct.user_id = um.ID)
ON DUPLICATE KEY UPDATE
collage_total = VALUES(collage_total),
collage_contrib = VALUES(collage_contrib)
");
self::$db->prepared_query("
INSERT INTO user_summary_new (user_id, download_total, download_unique)
SELECT ud.UserID,
count(*) AS total,
count(DISTINCT ud.TorrentID) AS 'unique'
FROM users_downloads AS ud
INNER JOIN torrents AS t ON (t.ID = ud.TorrentID)
INNER JOIN users_main um ON (um.ID = ud.UserID)
GROUP BY ud.UserID
ON DUPLICATE KEY UPDATE
download_total = VALUES(download_total),
download_unique = VALUES(download_unique)
");
self::$db->prepared_query("
INSERT INTO user_summary_new (user_id, fl_token_total)
SELECT uf.UserID, count(*) AS fl_token_total
FROM users_freeleeches uf
INNER JOIN users_main um ON (um.ID = uf.UserID)
GROUP BY uf.UserID
ON DUPLICATE KEY UPDATE
fl_token_total = VALUES(fl_token_total)
");
self::$db->prepared_query("
INSERT INTO user_summary_new (user_id, forum_post_total)
SELECT fp.AuthorID, count(*) AS forum_post_total
FROM forums_posts fp
INNER JOIN users_main um ON (um.ID = fp.AuthorID)
GROUP BY fp.AuthorID
ON DUPLICATE KEY UPDATE
forum_post_total = VALUES(forum_post_total)
");
self::$db->prepared_query("
INSERT INTO user_summary_new (user_id, forum_thread_total)
SELECT ft.AuthorID, count(*) AS forum_thread_total
FROM forums_topics ft
INNER JOIN users_main um ON (um.ID = ft.AuthorID)
GROUP BY ft.AuthorID
ON DUPLICATE KEY UPDATE
forum_thread_total = VALUES(forum_thread_total)
");
self::$db->prepared_query("
INSERT INTO user_summary_new (user_id, invited_total)
SELECT um.inviter_user_id, count(*) AS invited_total
FROM users_main um
WHERE um.inviter_user_id > 0
GROUP BY um.inviter_user_id
ON DUPLICATE KEY UPDATE
invited_total = VALUES(invited_total)
");
self::$db->prepared_query("
INSERT INTO user_summary_new (user_id, unique_group_total, upload_total)
SELECT t.UserID,
count(DISTINCT GroupID) AS unique_group_total,
count(*) AS upload_total
FROM torrents t
INNER JOIN users_main um ON (um.ID = t.UserID)
GROUP BY t.UserID
ON DUPLICATE KEY UPDATE
unique_group_total = VALUES(unique_group_total),
upload_total = VALUES(upload_total)
");
self::$db->prepared_query("
INSERT INTO user_summary_new (user_id, perfect_flac_total)
SELECT t.UserID, count(DISTINCT t.GroupID) AS perfect_flac_total
FROM torrents t
INNER JOIN users_main um ON (um.ID = t.UserID)
WHERE t.Format = 'FLAC'
AND (
(t.Media = 'CD' AND t.LogScore = 100)
OR (t.Media IN ('Vinyl', 'WEB', 'DVD', 'Soundboard', 'Cassette', 'SACD', 'Blu-ray', 'DAT'))
)
GROUP BY t.UserID
ON DUPLICATE KEY UPDATE
perfect_flac_total = VALUES(perfect_flac_total)
");
self::$db->prepared_query("
INSERT INTO user_summary_new (user_id, perfecter_flac_total)
SELECT t.UserID, count(DISTINCT t.GroupID) AS perfecter_flac_total
FROM torrents t
INNER JOIN users_main um ON (um.ID = t.UserID)
WHERE t.Format = 'FLAC'
AND (
(t.Media = 'CD' AND t.LogScore = 100)
OR (t.Media IN ('Vinyl', 'DVD', 'Soundboard', 'Cassette', 'SACD', 'Blu-ray', 'DAT'))
)
GROUP BY t.UserID
ON DUPLICATE KEY UPDATE
perfecter_flac_total = VALUES(perfecter_flac_total)
");
self::$db->prepared_query("
INSERT INTO user_summary_new (user_id, request_created_size, request_created_total, request_bounty_size, request_bounty_total, request_vote_size, request_vote_total)
WITH crea AS (
SELECT r.UserID,
count(*) AS total,
sum(rv.Bounty) AS bounty
FROM requests r
INNER JOIN requests_votes rv ON (rv.RequestID = r.ID AND rv.UserID = r.UserID)
GROUP BY UserID
),
filler AS (
SELECT r.FillerID,
count(DISTINCT r.id) AS total,
/**
* Note: exclude the bounty voted by a user on a request they filled themselves,
* as that increase has already been accounted for in users_leech_stats.Uploaded
*/
sum(CASE WHEN rv.UserID = r.FillerID THEN 0 ELSE rv.bounty END) AS bounty
FROM requests r
INNER JOIN requests_votes rv ON (rv.RequestID = r.ID)
WHERE r.FillerID > 0
GROUP BY r.FillerID
),
voter AS (
SELECT rv.UserID,
count(DISTINCT rv.RequestID) AS total,
sum(bounty) AS bounty
FROM requests_votes rv
GROUP BY rv.UserID
)
SELECT um.ID,
coalesce(crea.bounty, 0),
coalesce(crea.total, 0),
coalesce(filler.bounty, 0),
coalesce(filler.total, 0),
coalesce(voter.bounty, 0),
coalesce(voter.total, 0)
FROM users_main um
LEFT JOIN crea ON (crea.UserID = um.ID)
LEFT JOIN filler ON (filler.FillerID = um.ID)
LEFT JOIN voter ON (voter.UserID = um.ID)
WHERE (
crea.total IS NOT NULL
OR filler.total IS NOT NULL
OR voter.total IS NOT NULL
)
ON DUPLICATE KEY UPDATE
request_created_size = VALUES(request_created_size),
request_created_total = VALUES(request_created_total),
request_bounty_size = VALUES(request_bounty_size),
request_bounty_total = VALUES(request_bounty_total),
request_vote_size = VALUES(request_vote_size),
request_vote_total = VALUES(request_vote_total)
");
self::$db->prepared_query("
INSERT INTO user_summary_new (user_id, leech_total, seeding_total)
SELECT xfu.uid,
sum(case when xfu.remaining > 0 then 1 else 0 end) as leeching,
sum(case when xfu.remaining = 0 then 1 else 0 end) as seeding
FROM xbt_files_users AS xfu
INNER JOIN torrents AS t ON (t.ID = xfu.fid)
INNER JOIN users_main um ON (um.ID = xfu.uid)
WHERE um.Enabled = ?
GROUP BY xfu.uid
ON DUPLICATE KEY UPDATE
leech_total = VALUES(leech_total),
seeding_total = VALUES(seeding_total)
", UserStatus::enabled->value
);
self::$db->prepared_query("
INSERT INTO user_summary_new (user_id, bp_hourly_accrual)
SELECT xfu.uid,
sum(category_bonus_accrual(t.Size, xfh.seedtime, tls.Seeders, c.bonus_scale))
FROM (
SELECT DISTINCT uid, fid
FROM xbt_files_users
WHERE active = 1
AND remaining = 0
AND mtime > unix_timestamp(NOW() - INTERVAL 1 HOUR)
) AS xfu
INNER JOIN xbt_files_history xfh USING (uid, fid)
INNER JOIN torrents t ON (t.ID = xfu.fid)
INNER JOIN torrents_leech_stats tls ON (tls.TorrentID = t.ID)
INNER JOIN torrents_group tg ON (tg.ID = t.GroupID)
INNER JOIN category c ON (c.category_id = tg.CategoryID)
INNER JOIN users_main um ON (um.ID = xfu.uid)
WHERE um.Enabled = ?
GROUP BY xfu.uid
ON DUPLICATE KEY UPDATE
bp_hourly_accrual = VALUES(bp_hourly_accrual)
", UserStatus::enabled->value
);
self::$db->prepared_query("
INSERT INTO user_summary_new (user_id, snatch_total, snatch_unique)
SELECT xs.uid,
count(*) AS total,
count(DISTINCT xs.fid) AS 'unique'
FROM xbt_snatched AS xs
INNER JOIN torrents AS t ON (t.ID = xs.fid)
INNER JOIN users_main um ON (um.ID = xs.uid)
GROUP BY xs.uid
ON DUPLICATE KEY UPDATE
snatch_total = VALUES(snatch_total),
snatch_unique = VALUES(snatch_unique)
");
self::$db->prepared_query("
INSERT INTO user_summary_new (user_id, seedtime_hour)
SELECT xfh.uid,
sum(seedtime)
FROM xbt_files_history xfh
INNER JOIN users_main um ON (um.ID = xfh.uid)
INNER JOIN torrents t ON (t.ID = xfh.fid)
GROUP BY xfh.uid
ON DUPLICATE KEY UPDATE
seedtime_hour = VALUES(seedtime_hour)
");
self::$db->begin_transaction();
self::$db->prepared_query("
DELETE FROM user_summary
");
self::$db->prepared_query("
INSERT INTO user_summary
SELECT * FROM user_summary_new
");
$processed = self::$db->affected_rows();
self::$db->commit();
self::$db->dropTemporaryTable("user_summary_new");
return $processed;
}
public function refreshUseragentTracker(): int {
// NB: useragents may be null if the initial announce from ocelot
// was lost, e.g. because of a deadlock or queue overflow.
$result = $this->pg()->execute("
merge into history_useragent_tracker hut using (
select xfu.uid as id_user,
coalesce(xfu.useragent, '') as useragent,
count(*) as total
from relay.xbt_files_users xfu
group by xfu.uid, xfu.useragent
) as i on hut.id_user = i.id_user
and hut.useragent = i.useragent
when not matched and i.total > 0 then
insert ( id_user, useragent, total)
values (i.id_user, i.useragent, i.total)
when matched and i.total > 0 then
update set
total = i.total
when matched then
delete
");
return $result->getAffectedRows();
}
public function registerActivity(string $tableName, int $days): int {
if ($days > 0) {
self::$db->prepared_query("
DELETE FROM $tableName WHERE Time < now() - INTERVAL ? DAY
", $days
);
}
self::$db->prepared_query("
INSERT INTO $tableName (UserID, Uploaded, Downloaded, BonusPoints, Torrents, PerfectFLACs)
SELECT um.ID, uls.Uploaded, uls.Downloaded, coalesce(ub.points, 0), COUNT(t.ID) AS Torrents, COALESCE(p.Perfects, 0) AS PerfectFLACs
FROM users_main um
INNER JOIN users_leech_stats uls ON (uls.UserID = um.ID)
LEFT JOIN user_bonus ub ON (ub.user_id = um.ID)
LEFT JOIN torrents t ON (t.UserID = um.ID)
LEFT JOIN
(
SELECT UserID, count(*) AS Perfects
FROM torrents
WHERE Format = 'FLAC'
AND (
Media IN ('Vinyl', 'WEB', 'DVD', 'Soundboard', 'Cassette', 'SACD', 'BD', 'DAT')
OR
(Media = 'CD' AND LogScore = 100)
)
GROUP BY UserID
) p ON (p.UserID = um.ID)
GROUP BY um.ID
");
return self::$db->affected_rows();
}
public function browserList(): array {
self::$db->prepared_query("
SELECT Browser AS name,
BrowserVersion AS `version`,
count(*) AS total
FROM users_sessions
WHERE Browser IS NOT NULL
GROUP BY name, version
ORDER BY total DESC, name, version
");
return self::$db->to_array(false, MYSQLI_ASSOC);
}
public function operatingSystemList(): array {
self::$db->prepared_query("
SELECT OperatingSystem AS name,
OperatingSystemVersion AS version,
count(*) AS total
FROM users_sessions
WHERE OperatingSystem IS NOT NULL
GROUP BY name, version
ORDER BY total DESC, name, version
");
return self::$db->to_array(false, MYSQLI_ASSOC);
}
public function topDownloadList(int $limit): array {
$key = "topuserdl_$limit";
$top = self::$cache->get_value($key);
if ($top === false) {
self::$db->prepared_query("
SELECT um.ID
FROM users_main um
INNER JOIN users_leech_stats uls ON (uls.UserID = um.ID)
WHERE um.Enabled = ?
AND (um.Paranoia IS NULL OR um.Paranoia NOT REGEXP 'downloaded')
ORDER BY uls.Downloaded DESC
LIMIT ?
", UserStatus::enabled->value, $limit
);
$top = self::$db->collect(0);
self::$cache->cache_value($key, $top, 3600 * 12);
}
return $top;
}
public function topDownSpeedList(int $limit): array {
$key = "topuserds_$limit";
$top = self::$cache->get_value($key);
if ($top === false) {
self::$db->prepared_query("
SELECT um.ID
FROM users_main um
INNER JOIN users_leech_stats uls ON (uls.UserID = um.ID)
WHERE um.Enabled = ?
AND (um.Paranoia IS NULL OR um.Paranoia NOT REGEXP 'downloaded')
ORDER BY uls.Downloaded / (unix_timestamp(now()) - unix_timestamp(um.created)) DESC
LIMIT ?
", UserStatus::enabled->value, $limit
);
$top = self::$db->collect(0);
self::$cache->cache_value($key, $top, 3600 * 12);
}
return $top;
}
public function topUploadList(int $limit): array {
$key = "topuserul_$limit";
$top = self::$cache->get_value($key);
if ($top === false) {
self::$db->prepared_query("
SELECT um.ID
FROM users_main um
INNER JOIN users_leech_stats uls ON (uls.UserID = um.ID)
WHERE um.Enabled = ?
AND (um.Paranoia IS NULL OR um.Paranoia NOT REGEXP 'uploaded')
ORDER BY uls.Uploaded DESC
LIMIT ?
", UserStatus::enabled->value, $limit
);
$top = self::$db->collect(0);
self::$cache->cache_value($key, $top, 3600 * 12);
}
return $top;
}
public function topUpSpeedList(int $limit): array {
$key = "topuserus_$limit";
$top = self::$cache->get_value($key);
if ($top === false) {
self::$db->prepared_query("
SELECT um.ID
FROM users_main um
INNER JOIN users_leech_stats uls ON (uls.UserID = um.ID)
WHERE um.Enabled = ?
AND (um.Paranoia IS NULL OR um.Paranoia NOT REGEXP 'uploaded')
ORDER BY uls.Uploaded / (unix_timestamp(now()) - unix_timestamp(um.created)) DESC
LIMIT ?
", UserStatus::enabled->value, $limit
);
$top = self::$db->collect(0);
self::$cache->cache_value($key, $top, 3600 * 12);
}
return $top;
}
public function topTotalUploadList(int $limit): array {
$key = "topusertotup_$limit";
$top = self::$cache->get_value($key);
if ($top === false) {
self::$db->prepared_query("
SELECT um.ID
FROM users_main um
INNER JOIN user_summary us ON (us.user_id = um.ID)
WHERE um.Enabled = ?
AND (um.Paranoia IS NULL OR um.Paranoia NOT REGEXP 'uploaded')
ORDER BY us.upload_total DESC
LIMIT ?
", UserStatus::enabled->value, $limit
);
$top = self::$db->collect(0);
self::$cache->cache_value($key, $top, 3600 * 12);
}
return $top;
}
public function topTotalDownloadList(int $top, int $interval): array {
self::$db->prepared_query("
SELECT count(*) AS total,
ud.UserID AS user_id,
CASE WHEN prl.permission_id IS NOT NULL THEN 1 ELSE 0 END as limited,
CASE WHEN um.Enabled = ? THEN 1 ELSE 0 END as disabled
FROM users_downloads ud
INNER JOIN users_main um ON (um.ID = ud.UserID)
LEFT JOIN permission_rate_limit prl ON (prl.permission_id = um.PermissionID)
WHERE ud.Time >= now() - INTERVAL ? DAY
GROUP BY user_id, limited
ORDER BY total DESC, ud.UserID
LIMIT ?
", UserStatus::disabled->value, $interval, $top
);
return self::$db->to_array(false, MYSQLI_ASSOC);
}
}