[DATABASE] Fix remaining misuses of SQL's GROUP BY

This commit is contained in:
Alexei Sorokin 2020-08-10 19:29:04 +03:00 committed by Diogo Peralta Cordeiro
parent b0b10cf186
commit 03e69e8c31
5 changed files with 94 additions and 76 deletions

View File

@ -38,11 +38,15 @@ class GroupsByMembersSection extends GroupSection
{
$limit = GROUPS_PER_SECTION;
$qry = 'SELECT user_group.*, COUNT(*) AS value ' .
'FROM user_group INNER JOIN group_member '.
'ON user_group.id = group_member.group_id ' .
'GROUP BY user_group.id, user_group.nickname, user_group.fullname, user_group.homepage, user_group.description, user_group.location, user_group.original_logo, user_group.homepage_logo, user_group.stream_logo, user_group.mini_logo, user_group.created, user_group.modified ' .
'ORDER BY value DESC LIMIT ' . $limit;
$qry = <<<END
SELECT *
FROM user_group INNER JOIN (
SELECT group_id AS id, COUNT(group_id) AS value
FROM group_member
GROUP BY group_id
) AS t1 USING (id)
ORDER BY value DESC LIMIT {$limit};
END;
$group = Memcached_DataObject::cachedQuery('User_group', $qry, 3600);
return $group;

View File

@ -1,70 +1,66 @@
<?php
// This file is part of GNU social - https://www.gnu.org/software/social
//
// GNU social is free software: you can redistribute it and/or modify
// it under the terms of the GNU Affero General Public License as published by
// the Free Software Foundation, either version 3 of the License, or
// (at your option) any later version.
//
// GNU social is distributed in the hope that it will be useful,
// but WITHOUT ANY WARRANTY; without even the implied warranty of
// MERCHANTABILITY or FITNESS FOR A PARTICULAR PURPOSE. See the
// GNU Affero General Public License for more details.
//
// You should have received a copy of the GNU Affero General Public License
// along with GNU social. If not, see <http://www.gnu.org/licenses/>.
/**
* StatusNet, the distributed open-source microblogging tool
*
* Groups with the most posts section
*
* PHP version 5
*
* LICENCE: This program is free software: you can redistribute it and/or modify
* it under the terms of the GNU Affero General Public License as published by
* the Free Software Foundation, either version 3 of the License, or
* (at your option) any later version.
*
* This program is distributed in the hope that it will be useful,
* but WITHOUT ANY WARRANTY; without even the implied warranty of
* MERCHANTABILITY or FITNESS FOR A PARTICULAR PURPOSE. See the
* GNU Affero General Public License for more details.
*
* You should have received a copy of the GNU Affero General Public License
* along with this program. If not, see <http://www.gnu.org/licenses/>.
*
* @category Widget
* @package StatusNet
* @package GNUsocial
* @author Evan Prodromou <evan@status.net>
* @copyright 2009 StatusNet, Inc.
* @license http://www.fsf.org/licensing/licenses/agpl-3.0.html GNU Affero General Public License version 3.0
* @link http://status.net/
* @license https://www.gnu.org/licenses/agpl.html GNU AGPL v3 or later
*/
if (!defined('STATUSNET') && !defined('LACONICA')) {
exit(1);
}
defined('GNUSOCIAL') || die();
/**
* Groups with the most posts section
*
* @category Widget
* @package StatusNet
* @author Evan Prodromou <evan@status.net>
* @license http://www.fsf.org/licensing/licenses/agpl-3.0.html GNU Affero General Public License version 3.0
* @link http://status.net/
* @category Widget
* @package GNUsocial
* @author Evan Prodromou <evan@status.net>
* @license https://www.gnu.org/licenses/agpl.html GNU AGPL v3 or later
*/
class GroupsByPostsSection extends GroupSection
{
function getGroups()
public function getGroups()
{
$limit = GROUPS_PER_SECTION;
$qry = 'SELECT user_group.*, count(*) as value ' .
'FROM user_group JOIN group_inbox '.
'ON user_group.id = group_inbox.group_id ' .
'GROUP BY user_group.id,user_group.nickname,user_group.fullname,user_group.homepage,user_group.description,user_group.location,user_group.original_logo,user_group.homepage_logo,user_group.stream_logo,user_group.mini_logo,user_group.created,user_group.modified ' .
'ORDER BY value DESC LIMIT ' . $limit;
$qry = <<<END
SELECT *
FROM user_group INNER JOIN (
SELECT group_id AS id, COUNT(group_id) AS value
FROM group_inbox
GROUP BY group_id
) AS t1 USING (id)
ORDER BY value DESC LIMIT {$limit};
END;
$group = Memcached_DataObject::cachedQuery('User_group',
$qry,
3600);
$group = Memcached_DataObject::cachedQuery('User_group', $qry, 3600);
return $group;
}
function title()
public function title()
{
// TRANS: Title for groups with the most posts section.
return _('Active groups');
}
function divId()
public function divId()
{
return 'top_groups_by_post';
}

View File

@ -41,11 +41,19 @@ class TopPostersSection extends ProfileSection
{
$limit = PROFILES_PER_SECTION;
$qry = 'SELECT profile.*, COUNT(*) AS value ' .
'FROM profile JOIN notice ON profile.id = notice.profile_id ' .
(common_config('public', 'localonly') ? 'WHERE is_local = 1 ' : '') .
'GROUP BY profile.id, nickname, fullname, profileurl, homepage, bio, location, profile.created, profile.modified ' .
'ORDER BY value DESC LIMIT ' . $limit;
$qry = sprintf(
<<<'END'
SELECT *
FROM profile INNER JOIN (
SELECT profile_id AS id, COUNT(profile_id) AS value
FROM notice
%1$sGROUP BY profile_id
) AS t1 USING (id)
ORDER BY value DESC LIMIT %2$d;
END,
(common_config('public', 'localonly') ? 'WHERE notice.is_local = 1 ' : ''),
$limit
);
$profile = Memcached_DataObject::cachedQuery('Profile', $qry, 6 * 3600);
return $profile;

View File

@ -62,20 +62,25 @@ class GroupFavoritedAction extends ShowgroupAction
$groupId = (int)$this->group->id;
$weightexpr = common_sql_weight('fave.modified', common_config('popular', 'dropoff'));
$cutoff = sprintf(
"fave.modified > TIMESTAMP '%s'",
common_sql_date(time() - common_config('popular', 'cutoff'))
"fave.modified > CURRENT_TIMESTAMP - INTERVAL '%d' SECOND",
common_config('popular', 'cutoff')
);
$offset = ($this->page - 1) * NOTICES_PER_PAGE;
$limit = NOTICES_PER_PAGE + 1;
$limit = NOTICES_PER_PAGE + 1;
$qry = 'SELECT notice.*, ' . $weightexpr . ' AS weight ' .
'FROM notice ' .
'INNER JOIN group_inbox ON notice.id = group_inbox.notice_id ' .
'INNER JOIN fave ON notice.id = fave.notice_id ' .
'WHERE ' . $cutoff . ' AND group_id = ' . $groupId . ' ' .
'GROUP BY id, profile_id, uri, content, rendered, url, created, notice.modified, reply_to, is_local, source, notice.conversation ' .
'ORDER BY weight DESC LIMIT ' . $limit . ' OFFSET ' . $offset;
$qry = <<<END
SELECT *
FROM notice INNER JOIN (
SELECT notice_id AS id, {$weightexpr} AS weight
FROM fave
INNER JOIN group_inbox USING (notice_id)
WHERE {$cutoff} AND group_inbox.group_id = {$groupId}
GROUP BY notice_id
) AS t1 USING (id)
ORDER BY weight DESC
LIMIT {$limit} OFFSET {$offset};
END;
$notice = Memcached_DataObject::cachedQuery('Notice', $qry, 600);

View File

@ -77,18 +77,25 @@ class FavoritedSliceAction extends FavoritedAction
$weightexpr = common_sql_weight('fave.modified', common_config('popular', 'dropoff'));
$cutoff = sprintf(
"fave.modified > TIMESTAMP '%s'",
common_sql_date(time() - common_config('popular', 'cutoff'))
"fave.modified > CURRENT_TIMESTAMP - INTERVAL '%d' SECOND",
common_config('popular', 'cutoff')
);
$offset = ($this->page - 1) * NOTICES_PER_PAGE;
$limit = NOTICES_PER_PAGE + 1;
$qry = 'SELECT notice.*, ' . $weightexpr . ' AS weight ' .
'FROM notice INNER JOIN fave ON notice.id = fave.notice_id ' .
'WHERE ' . $cutoff . ' AND ' . $slice . ' ' .
'GROUP BY id, profile_id, uri, content, rendered, url, created, notice.modified, reply_to, is_local, source, notice.conversation ' .
'ORDER BY weight DESC LIMIT ' . $limit . ' OFFSET ' . $offset;
$qry = <<<END
SELECT *
FROM notice INNER JOIN (
SELECT notice.id, {$weightexpr} AS weight
FROM notice
INNER JOIN fave ON notice.id = fave.notice_id
WHERE {$cutoff} AND {$slice}
GROUP BY notice.id
) AS t1 USING (id)
ORDER BY weight DESC
LIMIT {$limit} OFFSET {$offset};
END;
$notice = Memcached_DataObject::cachedQuery('Notice', $qry, 600);
@ -113,17 +120,15 @@ class FavoritedSliceAction extends FavoritedAction
$include = $this->nicknamesToIds($this->includeUsers);
$exclude = $this->nicknamesToIds($this->excludeUsers);
if (count($include) == 1) {
return "profile_id = " . intval($include[0]);
} elseif (count($include) > 1) {
return "profile_id IN (" . implode(',', $include) . ")";
} elseif (count($exclude) === 1) {
return "profile_id != " . intval($exclude[0]);
} elseif (count($exclude) > 1) {
return "profile_id NOT IN (" . implode(',', $exclude) . ")";
} else {
return false;
$sql = [];
if (count($include) > 0) {
$sql[] = 'notice.profile_id IN (' . implode(',', $include) . ')';
}
if (count($exclude) > 0) {
$sql[] = 'notice.profile_id NOT IN (' . implode(',', $exclude) . ')';
}
return implode(' AND ', $sql) ?: false;
}
/**