diff --git a/classes/security/UserGroupDAO.inc.php b/classes/security/UserGroupDAO.inc.php index 5fbdc7ba9d5..6f9ecc57503 100644 --- a/classes/security/UserGroupDAO.inc.php +++ b/classes/security/UserGroupDAO.inc.php @@ -18,6 +18,10 @@ import('lib.pkp.classes.security.UserGroup'); import('lib.pkp.classes.workflow.WorkflowStageDAO'); +use Illuminate\Database\Capsule\Manager as Capsule; +use Illuminate\Database\MySqlConnection; +use Illuminate\Database\PostgresConnection; + class UserGroupDAO extends DAO { /** @var a shortcut to get the UserDAO **/ var $userDao; @@ -468,35 +472,55 @@ function getUsersNotInRole($roleId, $contextId = null, $search = null, $rangeInf * @return DAOResultFactory */ function getUsersById($userGroupId = null, $contextId = null, $searchType = null, $search = null, $searchMatch = null, $dbResultRange = null) { - $params = array_merge( - $this->userDao->getFetchParameters(), - [IDENTITY_SETTING_GIVENNAME, IDENTITY_SETTING_FAMILYNAME] - ); - if ($contextId) $params[] = (int) $contextId; - if ($userGroupId) $params[] = (int) $userGroupId; + $locale = AppLocale::getLocale(); + // The users register for the site, thus the site primary locale should be the default locale + $site = Application::get()->getRequest()->getSite(); + $primaryLocale = $site->getPrimaryLocale(); + + $settingValue = "( + SELECT us.setting_value + FROM user_settings AS us + WHERE + us.user_id = u.user_id + AND us.setting_name = ? + AND us.locale IN (?, ?) + -- First non-null/empty values, then give preference to the current locale + ORDER BY + COALESCE(us.setting_value, '') = '', us.locale <> ? + LIMIT 1 + )"; + $params = [ + IDENTITY_SETTING_GIVENNAME, $locale, $primaryLocale, $locale, + IDENTITY_SETTING_FAMILYNAME, $locale, $primaryLocale, $locale + ]; + $sql = "SELECT u.*, $settingValue AS user_given, $settingValue AS user_family + FROM users AS u + WHERE 1 = 1"; + + // Has user group + if ($contextId || $userGroupId) { + if ($contextId) { + $params[] = (int) $contextId; + } + if ($userGroupId) { + $params[] = (int) $userGroupId; + } + $sql .= ' AND EXISTS ( + SELECT 0 + FROM user_user_groups uug + INNER JOIN user_groups ug + ON ug.user_group_id = uug.user_group_id + WHERE + uug.user_id = u.user_id + ' . ($contextId ? 'AND ug.context_id = ?' : '') . ' + ' . ($userGroupId ? 'AND ug.user_group_id = ?' : '') . ' + )'; + } + $sql .= ' ' . $this->_getSearchSql($searchType, $search, $searchMatch, $params); // Get the result set - $result = $this->retrieveRange( - $sql = 'SELECT DISTINCT u.*, - ' . $this->userDao->getFetchColumns() .' - FROM users AS u - LEFT JOIN user_settings us ON (us.user_id = u.user_id AND us.setting_name = \'affiliation\') - LEFT JOIN user_interests ui ON (u.user_id = ui.user_id) - LEFT JOIN controlled_vocab_entry_settings cves ON (ui.controlled_vocab_entry_id = cves.controlled_vocab_entry_id) - LEFT JOIN user_user_groups uug ON (uug.user_id = u.user_id) - LEFT JOIN user_groups ug ON (ug.user_group_id = uug.user_group_id) - ' . $this->userDao->getFetchJoins() .' - LEFT JOIN user_settings usgs ON (usgs.user_id = u.user_id AND usgs.setting_name = ?) - LEFT JOIN user_settings usfs ON (usfs.user_id = u.user_id AND usfs.setting_name = ?) - - WHERE 1=1 ' . - ($contextId?'AND ug.context_id = ? ':'') . - ($userGroupId?'AND ug.user_group_id = ? ':'') . - $this->_getSearchSql($searchType, $search, $searchMatch, $params), - $params, - $dbResultRange - ); + $result = $this->retrieveRange($sql, $params, $dbResultRange); return new DAOResultFactory($result, $this->userDao, '_returnUserFromRowWithData', [], $sql, $params, $dbResultRange); } @@ -778,47 +802,82 @@ function deleteSettingsByLocale($locale) { * @return string SQL search snippet */ function _getSearchSql($searchType, $search, $searchMatch, &$params) { + $hasUserSetting = "EXISTS( + SELECT 0 + FROM user_settings + WHERE user_id = u.user_id + AND setting_name = '%s' + AND LOWER(setting_value) LIKE LOWER(?) + )"; $searchTypeMap = [ - IDENTITY_SETTING_GIVENNAME => 'usgs.setting_value', - IDENTITY_SETTING_FAMILYNAME => 'usfs.setting_value', - USER_FIELD_USERNAME => 'u.username', - USER_FIELD_EMAIL => 'u.email', - USER_FIELD_AFFILIATION => 'us.setting_value', + IDENTITY_SETTING_GIVENNAME => sprintf($hasUserSetting, IDENTITY_SETTING_GIVENNAME), + IDENTITY_SETTING_FAMILYNAME => sprintf($hasUserSetting, IDENTITY_SETTING_FAMILYNAME), + USER_FIELD_USERNAME => 'LOWER(u.username) LIKE LOWER(?)', + USER_FIELD_EMAIL => 'LOWER(u.email) LIKE LOWER(?)', + USER_FIELD_AFFILIATION => sprintf($hasUserSetting, USER_FIELD_AFFILIATION) ]; $searchSql = ''; - + $search = trim($search); if (!empty($search)) { - if (!isset($searchTypeMap[$searchType])) { - $str = $this->concat('COALESCE(usgs.setting_value,\'\')', 'COALESCE(usfs.setting_value,\'\')', 'u.email', 'COALESCE(us.setting_value,\'\')'); - $concatFields = ' ( LOWER(' . $str . ') LIKE ? OR LOWER(cves.setting_value) LIKE ? ) '; - - $search = strtolower($search); - - $words = preg_split('{\s+}', $search); - $searchFieldMap = array(); - - foreach ($words as $word) { - $searchFieldMap[] = $concatFields; - $term = '%' . $word . '%'; - array_push($params, $term, $term); + $terms = array_map(function ($term) { + return "%$term%"; + }, PKPString::regexp_split('/\s+/', $search)); + $filters = []; + + switch (get_class(Capsule::connection())) { + case MySqlConnection::class: + $concatSettingValue = "GROUP_CONCAT(setting_value SEPARATOR '')"; + break; + case PostgresConnection::class: + $concatSettingValue = "STRING_AGG(setting_value, '')"; + break; + default: + throw new DomainException('Unrecognized database'); } - - $searchSql .= ' AND ( ' . join(' AND ', $searchFieldMap) . ' ) '; + $userSetting = "COALESCE(( + SELECT $concatSettingValue + FROM user_settings + WHERE user_id = u.user_id + AND setting_name = '%s' + ), '')"; + + // Concat key user fields to search + $filters[] = '(1 = 1' . str_repeat(' AND LOWER(' . $this->concat( + sprintf($userSetting, IDENTITY_SETTING_GIVENNAME), + sprintf($userSetting, IDENTITY_SETTING_FAMILYNAME), + 'u.email', + sprintf($userSetting, USER_FIELD_AFFILIATION), + 'u.username' + ) . ') LIKE LOWER(?)', count($terms)) . ')'; + array_push($params, ...$terms); + + // Search the user interests + $filters[] = ' + EXISTS( + SELECT 0 + FROM user_interests ui + INNER JOIN controlled_vocab_entry_settings cves + ON ui.controlled_vocab_entry_id = cves.controlled_vocab_entry_id + WHERE + u.user_id = ui.user_id + ' . str_repeat(' AND LOWER(cves.setting_value) LIKE LOWER(?)', count($terms)) . ' + )'; + array_push($params, ...$terms); + + $searchSql .= 'AND (' . implode(' OR ', $filters) . ') '; } else { - $fieldName = $searchTypeMap[$searchType]; + $filter = $searchTypeMap[$searchType]; + $searchSql = "AND $filter"; switch ($searchMatch) { case 'is': - $searchSql = "AND LOWER($fieldName) = LOWER(?)"; $params[] = $search; break; case 'contains': - $searchSql = "AND LOWER($fieldName) LIKE LOWER(?)"; $params[] = '%' . $search . '%'; break; case 'startsWith': - $searchSql = "AND LOWER($fieldName) LIKE LOWER(?)"; $params[] = $search . '%'; break; } @@ -992,5 +1051,3 @@ static function getNotChangeMetadataEditPermissionRoles() { return [ROLE_ID_MANAGER]; } } - -