GUACAMOLE-1239: Update JDBC queries to handle case-sensitivity.

This commit is contained in:
Virtually Nick
2024-03-25 15:38:28 -04:00
parent 4d5101574a
commit 116f709454
38 changed files with 1210 additions and 241 deletions

View File

@@ -332,13 +332,24 @@ public class SQLServerEnvironment extends JDBCEnvironment {
@Override
public boolean getCaseSensitiveUsernames() throws GuacamoleException {
// SQL Server uses case-insensitive string searches by default, so
// we do not enforce case-sensitivity unless otherwise configured.
return getProperty(
// Get the configured or default value of the property.
boolean caseSensitiveUsernames = getProperty(
SQLServerGuacamoleProperties.SQLSERVER_CASE_SENSITIVE_USERNAMES,
false
super.getCaseSensitiveUsernames()
);
// If property has been set to true, warn the admin.
if (caseSensitiveUsernames)
logger.warn("You have configured this extension for case-sensitive "
+ "username comparisons, however, the default collations "
+ "for SQL Server databases do not support case-sensitive "
+ "string comparisons. Further database configuration may "
+ "be required in order for case-sensitive username "
+ "comparisons to function correctly.");
// Return as configured
return caseSensitiveUsernames;
}
}

View File

@@ -258,6 +258,13 @@ public class SQLServerGuacamoleProperties {
};
/**
* A property used to configure whether or not usernames within the SQL
* Server JDBC module should be treated as case-sensitive. While Guacamole
* will treat usernames as case-sensitive by default, SQL Server's default
* database collations do not do case-sensitive string comparisons, so in
* many cases this will effectively result in case-insensitive usernames.
*/
public static final BooleanGuacamoleProperty SQLSERVER_CASE_SENSITIVE_USERNAMES =
new BooleanGuacamoleProperty() {

View File

@@ -68,7 +68,14 @@
(SELECT user_id FROM [guacamole_user]
JOIN [guacamole_entity] ON [guacamole_user].entity_id = [guacamole_entity].entity_id
WHERE
[guacamole_entity].name = #{record.username,jdbcType=VARCHAR}
<choose>
<when test="caseSensitive">
[guacamole_entity].name = #{record.username,jdbcType=VARCHAR}
</when>
<otherwise>
LOWER([guacamole_entity].name) = LOWER(#{record.username,jdbcType=VARCHAR})
</otherwise>
</choose>
AND [guacamole_entity].type = 'USER'),
#{record.username,jdbcType=VARCHAR},
#{record.startDate,jdbcType=TIMESTAMP},
@@ -110,7 +117,15 @@
[guacamole_connection_history].user_id IN (
SELECT user_id
FROM [guacamole_user]
WHERE CHARINDEX(#{term.term,jdbcType=VARCHAR}, username) > 0
WHERE
<choose>
<when test="caseSensitive">
CHARINDEX(#{term.term,jdbcType=VARCHAR} IN username) > 0
</when>
<otherwise>
CHARINDEX(LOWER(#{term.term,jdbcType=VARCHAR}) IN LOWER(username)) > 0
</otherwise>
</choose>
)
OR [guacamole_connection_history].connection_id IN (
@@ -196,7 +211,14 @@
FROM [guacamole_user]
JOIN [guacamole_entity] ON [guacamole_user].entity_id = [guacamole_entity].entity_id
WHERE
CHARINDEX(#{term.term,jdbcType=VARCHAR}, [guacamole_entity].name) > 0
<choose>
<hen test="caseSensitive">
CHARINDEX(#{term.term,jdbcType=VARCHAR} IN [guacamole_entity].name) > 0
</when>
<otherwise>
CHARINDEX(LOWER(#{term.term,jdbcType=VARCHAR}) IN LOWER(guacamole_entity.name)) > 0
</otherwise>
</choose>
AND [guacamole_entity].type = 'USER'
)

View File

@@ -68,7 +68,15 @@
<property name="groups" value="effectiveGroups"/>
</include>
AND permission = #{type,jdbcType=VARCHAR}
AND affected_entity.name = #{identifier,jdbcType=VARCHAR}
AND
<choose>
<when test="caseSensitive">
affected_entity.name = #{identifier,jdbcType=VARCHAR}
</when>
<otherwise>
LOWER(affected_entity.name) = LOWER(#{identifier,jdbcType=VARCHAR})
</otherwise>
</choose>
AND affected_entity.type = 'USER'
</select>
@@ -86,11 +94,23 @@
<property name="entityID" value="#{entity.entityID,jdbcType=INTEGER}"/>
<property name="groups" value="effectiveGroups"/>
</include>
AND affected_entity.name IN
<foreach collection="identifiers" item="identifier"
AND
<choose>
<when test="caseSensitive">
affected_entity.name IN
<foreach collection="identifiers" item="identifier"
open="(" separator="," close=")">
#{identifier,jdbcType=VARCHAR}
</foreach>
#{identifier,jdbcType=VARCHAR}
</foreach>
</when>
<otherwise>
LOWER(affected_entity.name) IN
<foreach collection="identifiers" item="identifier"
open="(" separator="," close=")">
LOWER(#{identifier,jdbcType=VARCHAR})
</foreach>
</otherwise>
</choose>
AND permission IN
<foreach collection="permissions" item="permission"
open="(" separator="," close=")">
@@ -112,8 +132,16 @@
open="(" separator=" OR " close=")">
([guacamole_user_permission].entity_id = #{permission.entityID,jdbcType=INTEGER} AND
permission = #{permission.type,jdbcType=VARCHAR} AND
affected_entity.name = #{permission.objectIdentifier,jdbcType=VARCHAR} AND
affected_entity.type = 'USER')
<choose>
<when test="caseSensitive">
affected_entity.name = #{permission.objectIdentifier,jdbcType=VARCHAR}
</when>
<otherwise>
LOWER(affected_entity.name = LOWER(#{permission.objectIdentifier,jdbcType=VARCHAR})
</otherwise>
</choose>
AND
affected_entity.type = 'USER')
</foreach>
</delete>
@@ -139,7 +167,14 @@
</foreach>
AS permissions
JOIN [guacamole_entity] affected_entity ON
affected_entity.name = permissions.affected_name
<choose>
<when test="caseSensitive">
affected_entity.name = permissions.affected_name
</when>
<otherwise>
LOWER(affected_entity.name) = LOWER(permissions.affected_name)
</otherwise>
</choose>
AND affected_entity.type = 'USER'
JOIN [guacamole_user] affected_user ON affected_user.entity_id = affected_entity.entity_id
WHERE NOT EXISTS (SELECT 1 FROM [guacamole_user_permission]

View File

@@ -43,7 +43,14 @@
JOIN [guacamole_user] ON [guacamole_user_password_history].user_id = [guacamole_user].user_id
JOIN [guacamole_entity] ON [guacamole_user].entity_id = [guacamole_entity].entity_id
WHERE
[guacamole_entity].name = #{username,jdbcType=VARCHAR}
<choose>
<when test="caseSensitive">
[guacamole_entity].name = #{username,jdbcType=VARCHAR}
</when>
<otherwise>
LOWER([guacamole_entity].name) = LOWER(#{username,jdbcType=VARCHAR})
</otherwise>
</choose>
ORDER BY
[guacamole_user_password_history].password_date DESC

View File

@@ -133,10 +133,26 @@
) AS last_active
FROM [guacamole_user]
JOIN [guacamole_entity] ON [guacamole_user].entity_id = [guacamole_entity].entity_id
WHERE [guacamole_entity].name IN
WHERE
<choose>
<when test="caseSensitive">
[guacamole_entity].name
</when>
<otherwise>
LOWER([guacamole_entity].name)
</otherwise>
</choose>
IN
<foreach collection="identifiers" item="identifier"
open="(" separator="," close=")">
#{identifier,jdbcType=VARCHAR}
open="(" separator="," close=")">
<choose>
<when test="caseSensitive">
#{identifier,jdbcType=VARCHAR}
</when>
<otherwise>
LOWER(#{identifier,jdbcType=VARCHAR})
</otherwise>
</choose>
</foreach>
AND [guacamole_entity].type = 'USER';
@@ -147,10 +163,26 @@
FROM [guacamole_user_attribute]
JOIN [guacamole_user] ON [guacamole_user].user_id = [guacamole_user_attribute].user_id
JOIN [guacamole_entity] ON [guacamole_user].entity_id = [guacamole_entity].entity_id
WHERE [guacamole_entity].name IN
WHERE
<choose>
<when test="caseSensitive">
[guacamole_entity].name
</when>
<otherwise>
LOWER([guacamole_entity].name)
</otherwise>
</choose>
IN
<foreach collection="identifiers" item="identifier"
open="(" separator="," close=")">
#{identifier,jdbcType=VARCHAR}
open="(" separator="," close=")">
<choose>
<when test="caseSensitive">
#{identifier,jdbcType=VARCHAR}
</when>
<otherwise>
LOWER(#{identifier,jdbcType=VARCHAR})
</otherwise>
</choose>
</foreach>
AND [guacamole_entity].type = 'USER';
@@ -185,10 +217,26 @@
) AS last_active
FROM [guacamole_user]
JOIN [guacamole_entity] ON [guacamole_user].entity_id = [guacamole_entity].entity_id
WHERE [guacamole_entity].name IN
WHERE
<choose>
<when test="caseSensitive">
[guacamole_entity].name
</when>
<otherwise>
LOWER([guacamole_entity].name)
</otherwise>
</choose>
IN
<foreach collection="identifiers" item="identifier"
open="(" separator="," close=")">
#{identifier,jdbcType=VARCHAR}
<choose>
<when test="caseSensitive">
#{identifier,jdbcType=VARCHAR}
</when>
<otherwise>
LOWER(#{identifier,jdbcType=VARCHAR})
</otherwise>
</choose>
</foreach>
AND [guacamole_entity].type = 'USER'
AND [guacamole_user].user_id IN (
@@ -205,10 +253,26 @@
FROM [guacamole_user_attribute]
JOIN [guacamole_user] ON [guacamole_user].user_id = [guacamole_user_attribute].user_id
JOIN [guacamole_entity] ON [guacamole_user].entity_id = [guacamole_entity].entity_id
WHERE [guacamole_entity].name IN
WHERE
<choose>
<when test="caseSensitive">
[guacamole_entity].name
</when>
<otherwise>
LOWER([guacamole_entity].name)
</otherwise>
</choose>
IN
<foreach collection="identifiers" item="identifier"
open="(" separator="," close=")">
#{identifier,jdbcType=VARCHAR}
<choose>
<when test="caseSensitive">
#{identifier,jdbcType=VARCHAR}
</when>
<otherwise>
LOWER(#{identifier,jdbcType=VARCHAR})
</otherwise>
</choose>
</foreach>
AND [guacamole_entity].type = 'USER'
AND [guacamole_user].user_id IN (
@@ -250,7 +314,14 @@
FROM [guacamole_user]
JOIN [guacamole_entity] ON [guacamole_user].entity_id = [guacamole_entity].entity_id
WHERE
[guacamole_entity].name = #{username,jdbcType=VARCHAR}
<choose>
<when test="caseSensitive">
[guacamole_entity].name = #{username,jdbcType=VARCHAR}
</when>
<otherwise>
LOWER([guacamole_entity].name) = LOWER(#{username,jdbcType=VARCHAR})
</otherwise>
</choose>
AND [guacamole_entity].type = 'USER';
SELECT
@@ -261,7 +332,14 @@
JOIN [guacamole_user] ON [guacamole_user].user_id = [guacamole_user_attribute].user_id
JOIN [guacamole_entity] ON [guacamole_user].entity_id = [guacamole_entity].entity_id
WHERE
[guacamole_entity].name = #{username,jdbcType=VARCHAR}
<choose>
<when test="caseSensitive">
[guacamole_entity].name = #{username,jdbcType=VARCHAR}
</when>
<otherwise>
LOWER([guacamole_entity].name) = LOWER(#{username,jdbcType=VARCHAR})
</otherwise>
</choose>
AND [guacamole_entity].type = 'USER'
</select>
@@ -270,7 +348,14 @@
<delete id="delete">
DELETE FROM [guacamole_entity]
WHERE
name = #{identifier,jdbcType=VARCHAR}
<choose>
<when test="caseSensitive">
name = #{identifier,jdbcType=VARCHAR}
</when>
<otherwise>
LOWER(name) = LOWER(#{identifier,jdbcType=VARCHAR})
</otherwise>
</choose>
AND type = 'USER'
</delete>
@@ -332,7 +417,7 @@
email_address = #{object.emailAddress,jdbcType=VARCHAR},
organization = #{object.organization,jdbcType=VARCHAR},
organizational_role = #{object.organizationalRole,jdbcType=VARCHAR}
WHERE user_id = #{object.objectID,jdbcType=VARCHAR}
WHERE user_id = #{object.objectID,jdbcType=INTEGER}
</update>
<!-- Delete attributes associated with user -->

View File

@@ -49,8 +49,15 @@
(SELECT user_id FROM [guacamole_user]
JOIN [guacamole_entity] ON [guacamole_user].entity_id = [guacamole_entity].entity_id
WHERE
[guacamole_entity].name = #{record.username,jdbcType=VARCHAR}
AND [guacamole_entity].type = 'USER'),
<choose>
<when test="caseSensitive">
[guacamole_entity].name = #{record.username,jdbcType=VARCHAR}
</when>
<otherwise>
LOWER([guacamole_entity].name) = LOWER(#{record.username,jdbcType=VARCHAR})
</otherwise>
</choose>
AND [guacamole_entity].type = 'USER'),
#{record.username,jdbcType=VARCHAR},
#{record.startDate,jdbcType=TIMESTAMP},
#{record.endDate,jdbcType=TIMESTAMP}
@@ -81,7 +88,14 @@
<where>
<if test="identifier != null">
[guacamole_user_history].username = #{identifier,jdbcType=VARCHAR}
<choose>
<when test="caseSensitive">
[guacamole_user_history].username = #{identifier,jdbcType=VARCHAR}
</when>
<otherwise>
LOWER([guacamole_user_history].username) = LOWER(#{identifier,jdbcType=VARCHAR})
</otherwise>
</choose>
</if>
<foreach collection="terms" item="term" open=" AND " separator=" AND ">
@@ -92,7 +106,14 @@
FROM [guacamole_user]
JOIN [guacamole_entity] ON [guacamole_user].entity_id = [guacamole_entity].entity_id
WHERE
CHARINDEX(#{term.term,jdbcType=VARCHAR}, [guacamole_entity].name) > 0
<choose>
<when test="caseSensitive">
CHARINDEX(#{term.term,jdbcType=VARCHAR} IN [guacamole_entity].name) > 0
</when>
<otherwise>
CHARINDEX(LOWER(#{term.term,jdbcType=VARCHAR}) IN LOWER([guacamole_entity].name)) > 0
</otherwise>
</choose>
AND [guacamole_entity].type = 'USER'),
)
@@ -144,7 +165,15 @@
)
<if test="identifier != null">
AND [guacamole_entity].name = #{identifier,jdbcType=VARCHAR}
AND
<choose>
<when test="caseSensitive">
[guacamole_entity].name = #{identifier,jdbcType=VARCHAR}
</when>
<otherwise>
LOWER([guacamole_entity].name) = LOWER(#{identifier,jdbcType=VARCHAR})
</otherwise>
</choose>
</if>
<foreach collection="terms" item="term" open=" AND " separator=" AND ">
@@ -155,7 +184,14 @@
FROM [guacamole_user]
JOIN [guacamole_entity] ON [guacamole_user].entity_id = [guacamole_entity].entity_id
WHERE
CHARINDEX(#{term.term,jdbcType=VARCHAR}, [guacamole_entity].name) > 0
<choose>
<when test="caseSensitive">
CHARINDEX(#{term.term,jdbcType=VARCHAR} IN [guacamole_entity].name) > 0
</when>
<otherwise>
CHARINDEX(LOWER(#{term.term,jdbcType=VARCHAR}) IN LOWER([guacamole_entity].name)) > 0
</otherwise>
</choose>
AND [guacamole_entity].type = 'USER'
)

View File

@@ -58,11 +58,27 @@
WHERE
user_group_id = #{parent.objectID,jdbcType=INTEGER}
AND [guacamole_entity].type = 'USER'
AND [guacamole_entity].name IN
<foreach collection="children" item="identifier"
open="(" separator="," close=")">
#{identifier,jdbcType=VARCHAR}
</foreach>
AND
<choose>
<when test="caseSensitive">
[guacamole_entity].name
</when>
<otherwise>
LOWER([guacamole_entity].name)
</otherwise>
</choose>
IN
<foreach collection="children" item="identifier"
open="(" separator="," close=")">
<choose>
<when test="caseSensitive">
#{identifier,jdbcType=VARCHAR}
</when>
<otherwise>
LOWER(#{identifier,jdbcType=VARCHAR})
</otherwise>
</choose>
</foreach>
</delete>
<!-- Insert member users by name -->
@@ -76,11 +92,26 @@
[guacamole_entity].entity_id
FROM [guacamole_entity]
WHERE
[guacamole_entity].name IN
<foreach collection="children" item="identifier"
open="(" separator="," close=")">
#{identifier}
</foreach>
<choose>
<when test="caseSensitive">
[guacamole_entity].name
</when>
<otherwise>
LOWER([guacamole_entity].name)
</otherwise>
</choose>
IN
<foreach collection="children" item="identifier"
open="(" separator="," close=")">
<choose>
<when test="caseSensitive">
#{identifier}
</when>
<otherwise>
LOWER(#{identifier})
</otherwise>
</choose>
</foreach>
AND [guacamole_entity].type = 'USER'
AND [guacamole_entity].entity_id NOT IN (
SELECT [guacamole_user_group_member].member_entity_id