GUACAMOLE-96: Map base JDBC support for arbitrary attributes to SQL Server tables.

This commit is contained in:
Michael Jumper
2017-11-25 12:29:39 -08:00
parent 6a834a1066
commit 2d685766c0
6 changed files with 488 additions and 14 deletions

View File

@@ -241,6 +241,115 @@ CREATE NONCLUSTERED INDEX [IX_guacamole_sharing_profile_primary_connection_id]
ON [guacamole_sharing_profile] ([primary_connection_id]);
GO
--
-- Table of arbitrary user attributes. Each attribute is simply a name/value
-- pair associated with a user. Arbitrary attributes are defined by other
-- extensions. Attributes defined by this extension will be mapped to
-- properly-typed columns of a specific table.
--
CREATE TABLE [guacamole_user_attribute] (
[user_id] [int] NOT NULL,
[attribute_name] [nvarchar](128) NOT NULL,
[attribute_value] [nvarchar](4000) NOT NULL,
CONSTRAINT [PK_guacamole_user_attribute]
PRIMARY KEY CLUSTERED ([user_id], [attribute_name]),
CONSTRAINT [FK_guacamole_user_attribute_user_id]
FOREIGN KEY ([user_id])
REFERENCES [guacamole_user] ([user_id])
ON DELETE CASCADE
);
CREATE NONCLUSTERED INDEX [IX_guacamole_user_attribute_user_id]
ON [guacamole_user_attribute] ([user_id])
INCLUDE ([attribute_name], [attribute_value]);
GO
--
-- Table of arbitrary connection attributes. Each attribute is simply a
-- name/value pair associated with a connection. Arbitrary attributes are
-- defined by other extensions. Attributes defined by this extension will be
-- mapped to properly-typed columns of a specific table.
--
CREATE TABLE [guacamole_connection_attribute] (
[connection_id] [int] NOT NULL,
[attribute_name] [nvarchar](128) NOT NULL,
[attribute_value] [nvarchar](4000) NOT NULL,
PRIMARY KEY (connection_id, attribute_name),
CONSTRAINT [FK_guacamole_connection_attribute_connection_id]
FOREIGN KEY ([connection_id])
REFERENCES [guacamole_connection] ([connection_id])
ON DELETE CASCADE
);
CREATE NONCLUSTERED INDEX [IX_guacamole_connection_attribute_connection_id]
ON [guacamole_connection_attribute] ([connection_id])
INCLUDE ([attribute_name], [attribute_value]);
GO
--
-- Table of arbitrary connection group attributes. Each attribute is simply a
-- name/value pair associated with a connection group. Arbitrary attributes are
-- defined by other extensions. Attributes defined by this extension will be
-- mapped to properly-typed columns of a specific table.
--
CREATE TABLE [guacamole_connection_group_attribute] (
[connection_group_id] [int] NOT NULL,
[attribute_name] [nvarchar](128) NOT NULL,
[attribute_value] [nvarchar](4000) NOT NULL,
PRIMARY KEY (connection_group_id, attribute_name),
CONSTRAINT [FK_guacamole_connection_group_attribute_connection_group_id]
FOREIGN KEY ([connection_group_id])
REFERENCES [guacamole_connection_group] ([connection_group_id])
ON DELETE CASCADE
);
CREATE NONCLUSTERED INDEX [IX_guacamole_connection_group_attribute_connection_group_id]
ON [guacamole_connection_group_attribute] ([connection_group_id])
INCLUDE ([attribute_name], [attribute_value]);
GO
--
-- Table of arbitrary sharing profile attributes. Each attribute is simply a
-- name/value pair associated with a sharing profile. Arbitrary attributes are
-- defined by other extensions. Attributes defined by this extension will be
-- mapped to properly-typed columns of a specific table.
--
CREATE TABLE [guacamole_sharing_profile_attribute] (
[sharing_profile_id] [int] NOT NULL,
[attribute_name] [nvarchar](128) NOT NULL,
[attribute_value] [nvarchar](4000) NOT NULL,
PRIMARY KEY (sharing_profile_id, attribute_name),
CONSTRAINT [FK_guacamole_sharing_profile_attribute_sharing_profile_id]
FOREIGN KEY ([sharing_profile_id])
REFERENCES [guacamole_sharing_profile] ([sharing_profile_id])
ON DELETE CASCADE
);
CREATE NONCLUSTERED INDEX [IX_guacamole_sharing_profile_attribute_sharing_profile_id]
ON [guacamole_sharing_profile_attribute] ([sharing_profile_id])
INCLUDE ([attribute_name], [attribute_value]);
GO
--
-- Table of connection parameters. Each parameter is simply a name/value pair
-- associated with a connection.
@@ -683,3 +792,4 @@ AS BEGIN
END
GO

View File

@@ -0,0 +1,127 @@
--
-- 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.
--
--
-- Table of arbitrary user attributes. Each attribute is simply a name/value
-- pair associated with a user. Arbitrary attributes are defined by other
-- extensions. Attributes defined by this extension will be mapped to
-- properly-typed columns of a specific table.
--
CREATE TABLE [guacamole_user_attribute] (
[user_id] [int] NOT NULL,
[attribute_name] [nvarchar](128) NOT NULL,
[attribute_value] [nvarchar](4000) NOT NULL,
CONSTRAINT [PK_guacamole_user_attribute]
PRIMARY KEY CLUSTERED ([user_id], [attribute_name]),
CONSTRAINT [FK_guacamole_user_attribute_user_id]
FOREIGN KEY ([user_id])
REFERENCES [guacamole_user] ([user_id])
ON DELETE CASCADE
);
CREATE NONCLUSTERED INDEX [IX_guacamole_user_attribute_user_id]
ON [guacamole_user_attribute] ([user_id])
INCLUDE ([attribute_name], [attribute_value]);
GO
--
-- Table of arbitrary connection attributes. Each attribute is simply a
-- name/value pair associated with a connection. Arbitrary attributes are
-- defined by other extensions. Attributes defined by this extension will be
-- mapped to properly-typed columns of a specific table.
--
CREATE TABLE [guacamole_connection_attribute] (
[connection_id] [int] NOT NULL,
[attribute_name] [nvarchar](128) NOT NULL,
[attribute_value] [nvarchar](4000) NOT NULL,
PRIMARY KEY (connection_id, attribute_name),
CONSTRAINT [FK_guacamole_connection_attribute_connection_id]
FOREIGN KEY ([connection_id])
REFERENCES [guacamole_connection] ([connection_id])
ON DELETE CASCADE
);
CREATE NONCLUSTERED INDEX [IX_guacamole_connection_attribute_connection_id]
ON [guacamole_connection_attribute] ([connection_id])
INCLUDE ([attribute_name], [attribute_value]);
GO
--
-- Table of arbitrary connection group attributes. Each attribute is simply a
-- name/value pair associated with a connection group. Arbitrary attributes are
-- defined by other extensions. Attributes defined by this extension will be
-- mapped to properly-typed columns of a specific table.
--
CREATE TABLE [guacamole_connection_group_attribute] (
[connection_group_id] [int] NOT NULL,
[attribute_name] [nvarchar](128) NOT NULL,
[attribute_value] [nvarchar](4000) NOT NULL,
PRIMARY KEY (connection_group_id, attribute_name),
CONSTRAINT [FK_guacamole_connection_group_attribute_connection_group_id]
FOREIGN KEY ([connection_group_id])
REFERENCES [guacamole_connection_group] ([connection_group_id])
ON DELETE CASCADE
);
CREATE NONCLUSTERED INDEX [IX_guacamole_connection_group_attribute_connection_group_id]
ON [guacamole_connection_group_attribute] ([connection_group_id])
INCLUDE ([attribute_name], [attribute_value]);
GO
--
-- Table of arbitrary sharing profile attributes. Each attribute is simply a
-- name/value pair associated with a sharing profile. Arbitrary attributes are
-- defined by other extensions. Attributes defined by this extension will be
-- mapped to properly-typed columns of a specific table.
--
CREATE TABLE [guacamole_sharing_profile_attribute] (
[sharing_profile_id] [int] NOT NULL,
[attribute_name] [nvarchar](128) NOT NULL,
[attribute_value] [nvarchar](4000) NOT NULL,
PRIMARY KEY (sharing_profile_id, attribute_name),
CONSTRAINT [FK_guacamole_sharing_profile_attribute_sharing_profile_id]
FOREIGN KEY ([sharing_profile_id])
REFERENCES [guacamole_sharing_profile] ([sharing_profile_id])
ON DELETE CASCADE
);
CREATE NONCLUSTERED INDEX [IX_guacamole_sharing_profile_attribute_sharing_profile_id]
ON [guacamole_sharing_profile_attribute] ([sharing_profile_id])
INCLUDE ([attribute_name], [attribute_value]);
GO

View File

@@ -47,6 +47,14 @@
<result column="sharing_profile_id"/>
</collection>
<!-- Arbitrary attributes -->
<collection property="arbitraryAttributes" resultSet="arbitraryAttributes"
ofType="org.apache.guacamole.auth.jdbc.base.ArbitraryAttributeModel"
column="connection_id" foreignColumn="connection_id">
<result property="name" column="attribute_name" jdbcType="VARCHAR"/>
<result property="value" column="attribute_value" jdbcType="VARCHAR"/>
</collection>
</resultMap>
<!-- Select all connection identifiers -->
@@ -87,7 +95,7 @@
<!-- Select multiple connections by identifier -->
<select id="select" resultMap="ConnectionResultMap"
resultSets="connections,sharingProfiles">
resultSets="connections,sharingProfiles,arbitraryAttributes">
SELECT
[guacamole_connection].connection_id,
@@ -121,11 +129,22 @@
#{identifier,jdbcType=INTEGER}
</foreach>;
SELECT
connection_id,
attribute_name,
attribute_value
FROM [guacamole_connection_attribute]
WHERE connection_id IN
<foreach collection="identifiers" item="identifier"
open="(" separator="," close=")">
#{identifier,jdbcType=INTEGER}
</foreach>;
</select>
<!-- Select multiple connections by identifier only if readable -->
<select id="selectReadable" resultMap="ConnectionResultMap"
resultSets="connections,sharingProfiles">
resultSets="connections,sharingProfiles,arbitraryAttributes">
SELECT
[guacamole_connection].connection_id,
@@ -165,6 +184,20 @@
AND user_id = #{user.objectID,jdbcType=INTEGER}
AND permission = 'READ';
SELECT
[guacamole_connection_attribute].connection_id,
attribute_name,
attribute_value
FROM [guacamole_connection_attribute]
JOIN [guacamole_connection_permission] ON [guacamole_connection_permission].connection_id = [guacamole_connection_attribute].connection_id
WHERE [guacamole_connection_attribute].connection_id IN
<foreach collection="identifiers" item="identifier"
open="(" separator="," close=")">
#{identifier,jdbcType=INTEGER}
</foreach>
AND user_id = #{user.objectID,jdbcType=INTEGER}
AND permission = 'READ';
</select>
<!-- Select single connection by name -->
@@ -248,4 +281,25 @@
WHERE connection_id = #{object.objectID,jdbcType=INTEGER}
</update>
<!-- Delete attributes associated with connection -->
<delete id="deleteAttributes">
DELETE FROM [guacamole_connection_attribute]
WHERE connection_id = #{object.objectID,jdbcType=INTEGER}
</delete>
<!-- Insert attributes for connection -->
<insert id="insertAttributes" parameterType="org.apache.guacamole.auth.jdbc.base.ArbitraryAttributeModel">
INSERT INTO [guacamole_connection_attribute] (
connection_id,
attribute_name,
attribute_value
)
VALUES
<foreach collection="object.arbitraryAttributes" item="attribute" separator=",">
(#{object.objectID,jdbcType=INTEGER},
#{attribute.name,jdbcType=VARCHAR},
#{attribute.value,jdbcType=VARCHAR})
</foreach>
</insert>
</mapper>

View File

@@ -48,6 +48,14 @@
<result column="connection_id"/>
</collection>
<!-- Arbitrary attributes -->
<collection property="arbitraryAttributes" resultSet="arbitraryAttributes"
ofType="org.apache.guacamole.auth.jdbc.base.ArbitraryAttributeModel"
column="connection_group_id" foreignColumn="connection_group_id">
<result property="name" column="attribute_name" jdbcType="VARCHAR"/>
<result property="value" column="attribute_value" jdbcType="VARCHAR"/>
</collection>
</resultMap>
<!-- Select all connection group identifiers -->
@@ -88,7 +96,7 @@
<!-- Select multiple connection groups by identifier -->
<select id="select" resultMap="ConnectionGroupResultMap"
resultSets="connectionGroups,childConnectionGroups,childConnections">
resultSets="connectionGroups,childConnectionGroups,childConnections,arbitraryAttributes">
SELECT
connection_group_id,
@@ -121,11 +129,22 @@
#{identifier,jdbcType=INTEGER}
</foreach>;
SELECT
connection_group_id,
attribute_name,
attribute_value
FROM [guacamole_connection_group_attribute]
WHERE connection_group_id IN
<foreach collection="identifiers" item="identifier"
open="(" separator="," close=")">
#{identifier,jdbcType=INTEGER}
</foreach>;
</select>
<!-- Select multiple connection groups by identifier only if readable -->
<select id="selectReadable" resultMap="ConnectionGroupResultMap"
resultSets="connectionGroups,childConnectionGroups,childConnections">
resultSets="connectionGroups,childConnectionGroups,childConnections,arbitraryAttributes">
SELECT
[guacamole_connection_group].connection_group_id,
@@ -167,6 +186,20 @@
AND user_id = #{user.objectID,jdbcType=INTEGER}
AND permission = 'READ';
SELECT
[guacamole_connection_group_attribute].connection_group_id,
attribute_name,
attribute_value
FROM [guacamole_connection_group_attribute]
JOIN [guacamole_connection_group_permission] ON [guacamole_connection_group_permission].connection_group_id = [guacamole_connection_group_attribute].connection_group_id
WHERE [guacamole_connection_group_attribute].connection_group_id IN
<foreach collection="identifiers" item="identifier"
open="(" separator="," close=")">
#{identifier,jdbcType=INTEGER}
</foreach>
AND user_id = #{user.objectID,jdbcType=INTEGER}
AND permission = 'READ';
</select>
<!-- Select single connection group by name -->
@@ -229,4 +262,25 @@
WHERE connection_group_id = #{object.objectID,jdbcType=INTEGER}
</update>
<!-- Delete attributes associated with connection group -->
<delete id="deleteAttributes">
DELETE FROM [guacamole_connection_group_attribute]
WHERE connection_group_id = #{object.objectID,jdbcType=INTEGER}
</delete>
<!-- Insert attributes for connection group -->
<insert id="insertAttributes" parameterType="org.apache.guacamole.auth.jdbc.base.ArbitraryAttributeModel">
INSERT INTO [guacamole_connection_group_attribute] (
connection_group_id,
attribute_name,
attribute_value
)
VALUES
<foreach collection="object.arbitraryAttributes" item="attribute" separator=",">
(#{object.objectID,jdbcType=INTEGER},
#{attribute.name,jdbcType=VARCHAR},
#{attribute.value,jdbcType=VARCHAR})
</foreach>
</insert>
</mapper>

View File

@@ -25,9 +25,20 @@
<!-- Result mapper for sharing profile objects -->
<resultMap id="SharingProfileResultMap" type="org.apache.guacamole.auth.jdbc.sharingprofile.SharingProfileModel">
<!-- Sharing profile properties -->
<id column="sharing_profile_id" property="objectID" jdbcType="INTEGER"/>
<result column="sharing_profile_name" property="name" jdbcType="VARCHAR"/>
<result column="primary_connection_id" property="parentIdentifier" jdbcType="INTEGER"/>
<!-- Arbitrary attributes -->
<collection property="arbitraryAttributes" resultSet="arbitraryAttributes"
ofType="org.apache.guacamole.auth.jdbc.base.ArbitraryAttributeModel"
column="sharing_profile_id" foreignColumn="sharing_profile_id">
<result property="name" column="attribute_name" jdbcType="VARCHAR"/>
<result property="value" column="attribute_value" jdbcType="VARCHAR"/>
</collection>
</resultMap>
<!-- Select all sharing profile identifiers -->
@@ -46,7 +57,8 @@
</select>
<!-- Select multiple sharing profiles by identifier -->
<select id="select" resultMap="SharingProfileResultMap">
<select id="select" resultMap="SharingProfileResultMap"
resultSets="sharingProfiles,arbitraryAttributes">
SELECT
sharing_profile_id,
@@ -57,12 +69,24 @@
<foreach collection="identifiers" item="identifier"
open="(" separator="," close=")">
#{identifier,jdbcType=INTEGER}
</foreach>
</foreach>;
SELECT
sharing_profile_id,
attribute_name,
attribute_value
FROM [guacamole_sharing_profile_attribute]
WHERE sharing_profile_id IN
<foreach collection="identifiers" item="identifier"
open="(" separator="," close=")">
#{identifier,jdbcType=INTEGER}
</foreach>;
</select>
<!-- Select multiple sharing profiles by identifier only if readable -->
<select id="selectReadable" resultMap="SharingProfileResultMap">
<select id="selectReadable" resultMap="SharingProfileResultMap"
resultSets="sharingProfiles,arbitraryAttributes">
SELECT
[guacamole_sharing_profile].sharing_profile_id,
@@ -76,7 +100,21 @@
#{identifier,jdbcType=INTEGER}
</foreach>
AND user_id = #{user.objectID,jdbcType=INTEGER}
AND permission = 'READ'
AND permission = 'READ';
SELECT
[guacamole_sharing_profile_attribute].sharing_profile_id,
attribute_name,
attribute_value
FROM [guacamole_sharing_profile_attribute]
JOIN [guacamole_sharing_profile_permission] ON [guacamole_sharing_profile_permission].sharing_profile_id = [guacamole_sharing_profile_attribute].sharing_profile_id
WHERE [guacamole_sharing_profile_attribute].sharing_profile_id IN
<foreach collection="identifiers" item="identifier"
open="(" separator="," close=")">
#{identifier,jdbcType=INTEGER}
</foreach>
AND user_id = #{user.objectID,jdbcType=INTEGER}
AND permission = 'READ';
</select>
@@ -123,4 +161,25 @@
WHERE sharing_profile_id = #{object.objectID,jdbcType=INTEGER}
</update>
<!-- Delete attributes associated with sharing profile -->
<delete id="deleteAttributes">
DELETE FROM [guacamole_sharing_profile_attribute]
WHERE sharing_profile_id = #{object.objectID,jdbcType=INTEGER}
</delete>
<!-- Insert attributes for sharing profile -->
<insert id="insertAttributes" parameterType="org.apache.guacamole.auth.jdbc.base.ArbitraryAttributeModel">
INSERT INTO [guacamole_sharing_profile_attribute] (
sharing_profile_id,
attribute_name,
attribute_value
)
VALUES
<foreach collection="object.arbitraryAttributes" item="attribute" separator=",">
(#{object.objectID,jdbcType=INTEGER},
#{attribute.name,jdbcType=VARCHAR},
#{attribute.value,jdbcType=VARCHAR})
</foreach>
</insert>
</mapper>

View File

@@ -25,6 +25,8 @@
<!-- Result mapper for user objects -->
<resultMap id="UserResultMap" type="org.apache.guacamole.auth.jdbc.user.UserModel" >
<!-- User properties -->
<id column="user_id" property="objectID" jdbcType="INTEGER"/>
<result column="username" property="identifier" jdbcType="VARCHAR"/>
<result column="password_hash" property="passwordHash" jdbcType="BINARY"/>
@@ -42,6 +44,15 @@
<result column="organization" property="organization" jdbcType="VARCHAR"/>
<result column="organizational_role" property="organizationalRole" jdbcType="VARCHAR"/>
<result column="last_active" property="lastActive" jdbcType="TIMESTAMP"/>
<!-- Arbitrary attributes -->
<collection property="arbitraryAttributes" resultSet="arbitraryAttributes"
ofType="org.apache.guacamole.auth.jdbc.base.ArbitraryAttributeModel"
column="user_id" foreignColumn="user_id">
<result property="name" column="attribute_name" jdbcType="VARCHAR"/>
<result property="value" column="attribute_value" jdbcType="VARCHAR"/>
</collection>
</resultMap>
<!-- Select all usernames -->
@@ -61,7 +72,8 @@
</select>
<!-- Select multiple users by username -->
<select id="select" resultMap="UserResultMap">
<select id="select" resultMap="UserResultMap"
resultSets="users,arbitraryAttributes">
SELECT
[guacamole_user].user_id,
@@ -92,10 +104,23 @@
#{identifier,jdbcType=VARCHAR}
</foreach>;
SELECT
[guacamole_user_attribute].user_id,
[guacamole_user_attribute].attribute_name,
[guacamole_user_attribute].attribute_value
FROM [guacamole_user_attribute]
JOIN [guacamole_user] ON [guacamole_user].user_id = [guacamole_user_attribute].user_id
WHERE username IN
<foreach collection="identifiers" item="identifier"
open="(" separator="," close=")">
#{identifier,jdbcType=INTEGER}
</foreach>;
</select>
<!-- Select multiple users by username only if readable -->
<select id="selectReadable" resultMap="UserResultMap">
<select id="selectReadable" resultMap="UserResultMap"
resultSets="users,arbitraryAttributes">
SELECT
[guacamole_user].user_id,
@@ -127,12 +152,28 @@
#{identifier,jdbcType=VARCHAR}
</foreach>
AND [guacamole_user_permission].user_id = #{user.objectID,jdbcType=INTEGER}
AND permission = 'READ'
AND permission = 'READ';
SELECT
[guacamole_user_attribute].user_id,
[guacamole_user_attribute].attribute_name,
[guacamole_user_attribute].attribute_value
FROM [guacamole_user_attribute]
JOIN [guacamole_user] ON [guacamole_user].user_id = [guacamole_user_attribute].user_id
JOIN [guacamole_user_permission] ON affected_user_id = [guacamole_user].user_id
WHERE username IN
<foreach collection="identifiers" item="identifier"
open="(" separator="," close=")">
#{identifier,jdbcType=INTEGER}
</foreach>
AND [guacamole_user_permission].user_id = #{user.objectID,jdbcType=INTEGER}
AND permission = 'READ';
</select>
<!-- Select single user by username -->
<select id="selectOne" resultMap="UserResultMap">
<select id="selectOne" resultMap="UserResultMap"
resultSets="users,arbitraryAttributes">
SELECT
[guacamole_user].user_id,
@@ -159,7 +200,15 @@
FROM [guacamole_user]
LEFT JOIN [guacamole_user_history] ON [guacamole_user_history].user_id = [guacamole_user].user_id
WHERE
[guacamole_user].username = #{username,jdbcType=VARCHAR}
[guacamole_user].username = #{username,jdbcType=VARCHAR};
SELECT
[guacamole_user_attribute].user_id,
[guacamole_user_attribute].attribute_name,
[guacamole_user_attribute].attribute_value
FROM [guacamole_user_attribute]
JOIN [guacamole_user] ON [guacamole_user].user_id = [guacamole_user_attribute].user_id
WHERE username = #{username,jdbcType=VARCHAR};
</select>
@@ -230,4 +279,25 @@
WHERE user_id = #{object.objectID,jdbcType=VARCHAR}
</update>
<!-- Delete attributes associated with user -->
<delete id="deleteAttributes">
DELETE FROM [guacamole_user_attribute]
WHERE user_id = #{object.objectID,jdbcType=INTEGER}
</delete>
<!-- Insert attributes for user -->
<insert id="insertAttributes" parameterType="org.apache.guacamole.auth.jdbc.base.ArbitraryAttributeModel">
INSERT INTO [guacamole_user_attribute] (
user_id,
attribute_name,
attribute_value
)
VALUES
<foreach collection="object.arbitraryAttributes" item="attribute" separator=",">
(#{object.objectID,jdbcType=INTEGER},
#{attribute.name,jdbcType=VARCHAR},
#{attribute.value,jdbcType=VARCHAR})
</foreach>
</insert>
</mapper>