GUACAMOLE-220: Dynamically detect whether the MariaDB / MySQL server supports recursive CTEs.

This commit is contained in:
Michael Jumper
2018-09-08 18:11:36 -07:00
parent 204b6a4b24
commit dec7b3c340
8 changed files with 300 additions and 43 deletions

View File

@@ -19,11 +19,16 @@
package org.apache.guacamole.auth.mysql;
import java.sql.Connection;
import java.sql.DatabaseMetaData;
import java.sql.SQLException;
import org.apache.guacamole.GuacamoleException;
import org.apache.guacamole.auth.jdbc.JDBCEnvironment;
import org.slf4j.Logger;
import org.slf4j.LoggerFactory;
import org.apache.guacamole.auth.jdbc.security.PasswordPolicy;
import org.apache.ibatis.exceptions.PersistenceException;
import org.apache.ibatis.session.SqlSession;
/**
* A MySQL-specific implementation of JDBCEnvironment provides database
@@ -35,7 +40,17 @@ public class MySQLEnvironment extends JDBCEnvironment {
* Logger for this class.
*/
private static final Logger logger = LoggerFactory.getLogger(MySQLEnvironment.class);
/**
* The earliest version of MariaDB that supported recursive CTEs.
*/
private static final MySQLVersion MARIADB_SUPPORTS_CTE = new MySQLVersion(10, 2, 2, true);
/**
* The earliest version of MySQL that supported recursive CTEs.
*/
private static final MySQLVersion MYSQL_SUPPORTS_CTE = new MySQLVersion(8, 0, 1, false);
/**
* The default host to connect to, if MYSQL_HOSTNAME is not specified.
*/
@@ -227,8 +242,39 @@ public class MySQLEnvironment extends JDBCEnvironment {
}
@Override
public boolean isRecursiveQuerySupported() {
return false; // Only very recent versions of MySQL / MariaDB support recursive queries through CTEs
public boolean isRecursiveQuerySupported(SqlSession session) {
// Retrieve database version string from JDBC connection
String versionString;
try {
Connection connection = session.getConnection();
DatabaseMetaData metaData = connection.getMetaData();
versionString = metaData.getDatabaseProductVersion();
}
catch (SQLException e) {
throw new PersistenceException("Cannot determine whether "
+ "MySQL / MariaDB supports recursive queries.", e);
}
try {
// Parse MySQL / MariaDB version from version string
MySQLVersion version = new MySQLVersion(versionString);
logger.debug("Database recognized as {}.", version);
// Recursive queries are supported for MariaDB 10.2.2+ and
// MySQL 8.0.1+
return version.isAtLeast(MARIADB_SUPPORTS_CTE)
|| version.isAtLeast(MYSQL_SUPPORTS_CTE);
}
catch (IllegalArgumentException e) {
logger.debug("Unrecognized MySQL / MariaDB version string: "
+ "\"{}\". Assuming database engine does not support "
+ "recursive queries.", session);
return false;
}
}
}

View File

@@ -0,0 +1,153 @@
/*
* Licensed to the Apache Software Foundation (ASF) under one
* or more contributor license agreements. See the NOTICE file
* distributed with this work for additional information
* regarding copyright ownership. The ASF licenses this file
* to you under the Apache License, Version 2.0 (the
* "License"); you may not use this file except in compliance
* with the License. You may obtain a copy of the License at
*
* http://www.apache.org/licenses/LICENSE-2.0
*
* Unless required by applicable law or agreed to in writing,
* software distributed under the License is distributed on an
* "AS IS" BASIS, WITHOUT WARRANTIES OR CONDITIONS OF ANY
* KIND, either express or implied. See the License for the
* specific language governing permissions and limitations
* under the License.
*/
package org.apache.guacamole.auth.mysql;
import com.google.common.collect.ComparisonChain;
import java.util.regex.Matcher;
import java.util.regex.Pattern;
/**
* The specific version of a MySQL or MariaDB server.
*/
public class MySQLVersion {
/**
* Pattern which matches the version string returned by a MariaDB server,
* extracting the major, minor, and patch numbers.
*/
private final Pattern MARIADB_VERSION = Pattern.compile("^.*-([0-9]+)\\.([0-9]+)\\.([0-9]+)-MariaDB$");
/**
* Pattern which matches the version string returned by a non-MariaDB
* server (including MySQL and Aurora), extracting the major, minor, and
* patch numbers. All non-MariaDB servers use normal MySQL version numbers.
*/
private final Pattern MYSQL_VERSION = Pattern.compile("^([0-9]+)\\.([0-9]+)\\.([0-9]+).*$");
/**
* Whether the associated server is a MariaDB server. All non-MariaDB
* servers use normal MySQL version numbers and are comparable against each
* other.
*/
private final boolean isMariaDB;
/**
* The major component of the MAJOR.MINOR.PATCH version number.
*/
private final int major;
/**
* The minor component of the MAJOR.MINOR.PATCH version number.
*/
private final int minor;
/**
* The patch component of the MAJOR.MINOR.PATCH version number.
*/
private final int patch;
/**
* Creates a new MySQLVersion having the specified major, minor, and patch
* components.
*
* @param major
* The major component of the MAJOR.MINOR.PATCH version number of the
* MariaDB / MySQL server.
*
* @param minor
* The minor component of the MAJOR.MINOR.PATCH version number of the
* MariaDB / MySQL server.
*
* @param patch
* The patch component of the MAJOR.MINOR.PATCH version number of the
* MariaDB / MySQL server.
*
* @param isMariaDB
* Whether the associated server is a MariaDB server.
*/
public MySQLVersion(int major, int minor, int patch, boolean isMariaDB) {
this.major = major;
this.minor = minor;
this.patch = patch;
this.isMariaDB = isMariaDB;
}
public MySQLVersion(String version) throws IllegalArgumentException {
// Extract MariaDB version number if version string appears to be
// a MariaDB version string
Matcher mariadb = MARIADB_VERSION.matcher(version);
if (mariadb.matches()) {
this.major = Integer.parseInt(mariadb.group(1));
this.minor = Integer.parseInt(mariadb.group(2));
this.patch = Integer.parseInt(mariadb.group(3));
this.isMariaDB = true;
return;
}
// If not MariaDB, assume version string is a MySQL version string
// and attempt to extract the version number
Matcher mysql = MYSQL_VERSION.matcher(version);
if (mysql.matches()) {
this.major = Integer.parseInt(mysql.group(1));
this.minor = Integer.parseInt(mysql.group(2));
this.patch = Integer.parseInt(mysql.group(3));
this.isMariaDB = false;
return;
}
throw new IllegalArgumentException("Unrecognized MySQL / MariaDB version string.");
}
/**
* Returns whether this version is at least as recent as the given version.
*
* @param version
* The version to compare against.
*
* @return
* true if the versions are associated with the same database server
* type (MariaDB vs. MySQL) and this version is at least as recent as
* the given version, false otherwise.
*/
public boolean isAtLeast(MySQLVersion version) {
// If the databases use different version numbering schemes, the
// version numbers are not comparable
if (isMariaDB != version.isMariaDB)
return false;
// Compare major, minor, and patch number in order of precedence
return ComparisonChain.start()
.compare(major, version.major)
.compare(minor, version.minor)
.compare(patch, version.patch)
.result() >= 0;
}
@Override
public String toString() {
return String.format("%s %d.%d.%d", isMariaDB ? "MariaDB" : "MySQL",
major, minor, patch);
}
}

View File

@@ -65,43 +65,76 @@
<!-- Select names of all effective groups (including inherited) -->
<select id="selectEffectiveGroupIdentifiers" resultType="string">
WITH RECURSIVE related_entity(entity_id) AS (
SELECT
guacamole_user_group.entity_id
FROM guacamole_user_group
JOIN guacamole_user_group_member ON guacamole_user_group.user_group_id = guacamole_user_group_member.user_group_id
WHERE
<if test="!recursive">
SELECT
guacamole_entity.name
FROM guacamole_user_group
JOIN guacamole_entity ON guacamole_user_group.entity_id = guacamole_entity.entity_id
JOIN guacamole_user_group_member ON guacamole_user_group.user_group_id = guacamole_user_group_member.user_group_id
WHERE
guacamole_user_group.disabled = false
AND (
guacamole_user_group_member.member_entity_id = #{entity.entityID}
AND guacamole_user_group.disabled = false
<if test="!effectiveGroups.isEmpty()">
<if test="!effectiveGroups.isEmpty()">
OR guacamole_user_group_member.member_entity_id IN (
SELECT entity_id FROM guacamole_entity
WHERE type = 'USER_GROUP' AND name IN
<foreach collection="effectiveGroups" item="effectiveGroup"
open="(" separator="," close=")">
#{effectiveGroup,jdbcType=VARCHAR}
</foreach>
)
OR guacamole_user_group.entity_id IN (
SELECT entity_id FROM guacamole_entity
WHERE type = 'USER_GROUP' AND name IN
<foreach collection="effectiveGroups" item="effectiveGroup"
open="(" separator="," close=")">
#{effectiveGroup,jdbcType=VARCHAR}
</foreach>
)
</if>
)
</if>
<if test="recursive">
WITH RECURSIVE related_entity(entity_id) AS (
SELECT
guacamole_user_group.entity_id
FROM guacamole_user_group
JOIN guacamole_user_group_member ON guacamole_user_group.user_group_id = guacamole_user_group_member.user_group_id
WHERE
guacamole_user_group_member.member_entity_id = #{entity.entityID}
AND guacamole_user_group.disabled = false
<if test="!effectiveGroups.isEmpty()">
UNION
SELECT
guacamole_entity.entity_id
FROM guacamole_entity
JOIN guacamole_user_group ON guacamole_user_group.entity_id = guacamole_entity.entity_id
WHERE
type = 'USER_GROUP'
AND name IN
<foreach collection="effectiveGroups" item="effectiveGroup"
open="(" separator="," close=")">
#{effectiveGroup,jdbcType=VARCHAR}
</foreach>
AND guacamole_user_group.disabled = false
</if>
UNION
SELECT
guacamole_entity.entity_id
FROM guacamole_entity
JOIN guacamole_user_group ON guacamole_user_group.entity_id = guacamole_entity.entity_id
guacamole_user_group.entity_id
FROM related_entity
JOIN guacamole_user_group_member ON related_entity.entity_id = guacamole_user_group_member.member_entity_id
JOIN guacamole_user_group ON guacamole_user_group.user_group_id = guacamole_user_group_member.user_group_id
WHERE
type = 'USER_GROUP'
AND name IN
<foreach collection="effectiveGroups" item="effectiveGroup"
open="(" separator="," close=")">
#{effectiveGroup,jdbcType=VARCHAR}
</foreach>
AND guacamole_user_group.disabled = false
</if>
UNION
SELECT
guacamole_user_group.entity_id
FROM related_entity
JOIN guacamole_user_group_member ON related_entity.entity_id = guacamole_user_group_member.member_entity_id
JOIN guacamole_user_group ON guacamole_user_group.user_group_id = guacamole_user_group_member.user_group_id
WHERE
guacamole_user_group.disabled = false
)
SELECT name
FROM related_entity
JOIN guacamole_entity ON related_entity.entity_id = guacamole_entity.entity_id
WHERE
guacamole_entity.type = 'USER_GROUP';
guacamole_user_group.disabled = false
)
SELECT name
FROM related_entity
JOIN guacamole_entity ON related_entity.entity_id = guacamole_entity.entity_id
WHERE
guacamole_entity.type = 'USER_GROUP';
</if>
</select>