Add .gitignore and .ratignore files for various directories
Some checks failed
continuous-integration/drone/push Build is failing
Some checks failed
continuous-integration/drone/push Build is failing
This commit is contained in:
@@ -0,0 +1,973 @@
|
||||
--
|
||||
-- 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.
|
||||
--
|
||||
|
||||
--
|
||||
-- Connection group types
|
||||
--
|
||||
|
||||
CREATE RULE [guacamole_connection_group_type_list] AS @list IN (
|
||||
'ORGANIZATIONAL',
|
||||
'BALANCING'
|
||||
);
|
||||
GO
|
||||
|
||||
CREATE TYPE [guacamole_connection_group_type] FROM [nvarchar](16);
|
||||
EXEC sp_bindrule
|
||||
'guacamole_connection_group_type_list',
|
||||
'guacamole_connection_group_type';
|
||||
GO
|
||||
|
||||
--
|
||||
-- Entity types
|
||||
--
|
||||
|
||||
CREATE RULE [guacamole_entity_type_list] AS @list IN (
|
||||
'USER',
|
||||
'USER_GROUP'
|
||||
);
|
||||
GO
|
||||
|
||||
CREATE TYPE [guacamole_entity_type] FROM [nvarchar](16);
|
||||
EXEC sp_bindrule
|
||||
'guacamole_entity_type_list',
|
||||
'guacamole_entity_type';
|
||||
GO
|
||||
|
||||
--
|
||||
-- Object permission types
|
||||
--
|
||||
|
||||
CREATE RULE [guacamole_object_permission_list] AS @list IN (
|
||||
'READ',
|
||||
'UPDATE',
|
||||
'DELETE',
|
||||
'ADMINISTER'
|
||||
);
|
||||
GO
|
||||
|
||||
CREATE TYPE [guacamole_object_permission] FROM [nvarchar](16);
|
||||
EXEC sp_bindrule
|
||||
'guacamole_object_permission_list',
|
||||
'guacamole_object_permission';
|
||||
GO
|
||||
|
||||
--
|
||||
-- System permission types
|
||||
--
|
||||
|
||||
CREATE RULE [guacamole_system_permission_list] AS @list IN (
|
||||
'CREATE_CONNECTION',
|
||||
'CREATE_CONNECTION_GROUP',
|
||||
'CREATE_SHARING_PROFILE',
|
||||
'CREATE_USER',
|
||||
'CREATE_USER_GROUP',
|
||||
'AUDIT',
|
||||
'ADMINISTER'
|
||||
);
|
||||
GO
|
||||
|
||||
CREATE TYPE [guacamole_system_permission] FROM [nvarchar](32);
|
||||
EXEC sp_bindrule
|
||||
'guacamole_system_permission_list',
|
||||
'guacamole_system_permission';
|
||||
GO
|
||||
|
||||
--
|
||||
-- Guacamole proxy (guacd) encryption methods.
|
||||
--
|
||||
|
||||
CREATE RULE [guacamole_proxy_encryption_method_list] AS @list IN (
|
||||
'NONE',
|
||||
'SSL'
|
||||
);
|
||||
GO
|
||||
|
||||
CREATE TYPE [guacamole_proxy_encryption_method] FROM [nvarchar](8);
|
||||
EXEC sp_bindrule
|
||||
'guacamole_proxy_encryption_method_list',
|
||||
'guacamole_proxy_encryption_method';
|
||||
GO
|
||||
|
||||
--
|
||||
-- Table of connection groups. Each connection group has a name, type, and
|
||||
-- optional parent connection group.
|
||||
--
|
||||
|
||||
CREATE TABLE [guacamole_connection_group] (
|
||||
|
||||
[connection_group_id] [int] IDENTITY(1,1) NOT NULL,
|
||||
[parent_id] [int],
|
||||
[connection_group_name] [nvarchar](128) NOT NULL,
|
||||
[type] [guacamole_connection_group_type]
|
||||
NOT NULL DEFAULT 'ORGANIZATIONAL',
|
||||
|
||||
-- Concurrency limits
|
||||
[max_connections] [int],
|
||||
[max_connections_per_user] [int],
|
||||
[enable_session_affinity] [bit] NOT NULL DEFAULT 0,
|
||||
|
||||
CONSTRAINT [PK_guacamole_connection_group]
|
||||
PRIMARY KEY CLUSTERED ([connection_group_id]),
|
||||
|
||||
CONSTRAINT [AK_guacamole_connection_group_name_parent]
|
||||
UNIQUE ([connection_group_name], [parent_id]),
|
||||
|
||||
CONSTRAINT [FK_guacamole_connection_group_parent_id]
|
||||
FOREIGN KEY ([parent_id])
|
||||
REFERENCES [guacamole_connection_group] ([connection_group_id])
|
||||
-- ON DELETE CASCADE handled by guacamole_delete_connection_group trigger
|
||||
|
||||
);
|
||||
|
||||
CREATE NONCLUSTERED INDEX [IX_guacamole_connection_group_parent_id]
|
||||
ON [guacamole_connection_group] ([parent_id]);
|
||||
GO
|
||||
|
||||
--
|
||||
-- Table of connections. Each connection has a name, protocol, and
|
||||
-- associated set of parameters. A connection may belong to a connection group.
|
||||
--
|
||||
|
||||
CREATE TABLE [guacamole_connection] (
|
||||
|
||||
[connection_id] [int] IDENTITY(1,1) NOT NULL,
|
||||
[connection_name] [nvarchar](128) NOT NULL,
|
||||
[parent_id] [int],
|
||||
[protocol] [nvarchar](32) NOT NULL,
|
||||
|
||||
-- Concurrency limits
|
||||
[max_connections] [int],
|
||||
[max_connections_per_user] [int],
|
||||
|
||||
-- Connection Weight
|
||||
[connection_weight] [int],
|
||||
[failover_only] [bit] NOT NULL DEFAULT 0,
|
||||
|
||||
-- Guacamole proxy (guacd) overrides
|
||||
[proxy_port] [int],
|
||||
[proxy_hostname] [nvarchar](512),
|
||||
[proxy_encryption_method] [guacamole_proxy_encryption_method],
|
||||
|
||||
CONSTRAINT [PK_guacamole_connection]
|
||||
PRIMARY KEY CLUSTERED ([connection_id]),
|
||||
|
||||
CONSTRAINT [AK_guacamole_connection_name_parent]
|
||||
UNIQUE ([connection_name], [parent_id]),
|
||||
|
||||
CONSTRAINT [FK_guacamole_connection_parent_id]
|
||||
FOREIGN KEY ([parent_id])
|
||||
REFERENCES [guacamole_connection_group] ([connection_group_id])
|
||||
-- ON DELETE CASCADE handled by guacamole_delete_connection_group trigger
|
||||
|
||||
);
|
||||
|
||||
CREATE NONCLUSTERED INDEX [IX_guacamole_connection_parent_id]
|
||||
ON [guacamole_connection] ([parent_id]);
|
||||
GO
|
||||
|
||||
--
|
||||
-- Table of base entities which may each be either a user or user group. Other
|
||||
-- tables which represent qualities shared by both users and groups will point
|
||||
-- to guacamole_entity, while tables which represent qualities specific to
|
||||
-- users or groups will point to guacamole_user or guacamole_user_group.
|
||||
--
|
||||
|
||||
CREATE TABLE [guacamole_entity] (
|
||||
|
||||
[entity_id] [int] IDENTITY(1,1) NOT NULL,
|
||||
[name] [nvarchar](128) NOT NULL,
|
||||
[type] [guacamole_entity_type] NOT NULL,
|
||||
|
||||
CONSTRAINT [PK_guacamole_entity]
|
||||
PRIMARY KEY CLUSTERED ([entity_id]),
|
||||
|
||||
CONSTRAINT [AK_guacamole_entity_name_scope]
|
||||
UNIQUE ([type], [name])
|
||||
|
||||
);
|
||||
GO
|
||||
|
||||
--
|
||||
-- Table of users. Each user has a unique username and a hashed password
|
||||
-- with corresponding salt. Although the authentication system will always set
|
||||
-- salted passwords, other systems may set unsalted passwords by simply not
|
||||
-- providing the salt.
|
||||
--
|
||||
|
||||
CREATE TABLE [guacamole_user] (
|
||||
|
||||
[user_id] [int] IDENTITY(1,1) NOT NULL,
|
||||
[entity_id] [int] NOT NULL,
|
||||
|
||||
-- Optionally-salted password
|
||||
[password_hash] [binary](32) NOT NULL,
|
||||
[password_salt] [binary](32),
|
||||
[password_date] [datetime] NOT NULL,
|
||||
|
||||
-- Account disabled/expired status
|
||||
[disabled] [bit] NOT NULL DEFAULT 0,
|
||||
[expired] [bit] NOT NULL DEFAULT 0,
|
||||
|
||||
-- Time-based access restriction
|
||||
[access_window_start] [time](7),
|
||||
[access_window_end] [time](7),
|
||||
|
||||
-- Date-based access restriction
|
||||
[valid_from] [date],
|
||||
[valid_until] [date],
|
||||
|
||||
-- Timezone used for all date/time comparisons and interpretation
|
||||
[timezone] [nvarchar](64),
|
||||
|
||||
-- Profile information
|
||||
[full_name] [nvarchar](256),
|
||||
[email_address] [nvarchar](256),
|
||||
[organization] [nvarchar](256),
|
||||
[organizational_role] [nvarchar](256),
|
||||
|
||||
CONSTRAINT [PK_guacamole_user]
|
||||
PRIMARY KEY CLUSTERED ([user_id]),
|
||||
|
||||
CONSTRAINT [AK_guacamole_user_single_entity]
|
||||
UNIQUE ([entity_id]),
|
||||
|
||||
CONSTRAINT [FK_guacamole_user_entity]
|
||||
FOREIGN KEY ([entity_id])
|
||||
REFERENCES [guacamole_entity] ([entity_id])
|
||||
ON DELETE CASCADE
|
||||
|
||||
);
|
||||
GO
|
||||
|
||||
--
|
||||
-- Table of user groups. Each user group may have an arbitrary set of member
|
||||
-- users and member groups, with those members inheriting the permissions
|
||||
-- granted to that group.
|
||||
--
|
||||
|
||||
CREATE TABLE [guacamole_user_group] (
|
||||
|
||||
[user_group_id] [int] IDENTITY(1,1) NOT NULL,
|
||||
[entity_id] [int] NOT NULL,
|
||||
|
||||
-- Group disabled status
|
||||
[disabled] [bit] NOT NULL DEFAULT 0,
|
||||
|
||||
CONSTRAINT [PK_guacamole_user_group]
|
||||
PRIMARY KEY CLUSTERED ([user_group_id]),
|
||||
|
||||
CONSTRAINT [guacamole_user_group_single_entity]
|
||||
UNIQUE ([entity_id]),
|
||||
|
||||
CONSTRAINT [guacamole_user_group_entity]
|
||||
FOREIGN KEY ([entity_id])
|
||||
REFERENCES [guacamole_entity] ([entity_id])
|
||||
ON DELETE CASCADE
|
||||
|
||||
);
|
||||
GO
|
||||
|
||||
--
|
||||
-- Table of users which are members of given user groups.
|
||||
--
|
||||
|
||||
CREATE TABLE [guacamole_user_group_member] (
|
||||
|
||||
[user_group_id] [int] NOT NULL,
|
||||
[member_entity_id] [int] NOT NULL,
|
||||
|
||||
CONSTRAINT [PK_guacamole_user_group_member]
|
||||
PRIMARY KEY CLUSTERED ([user_group_id], [member_entity_id]),
|
||||
|
||||
-- Parent must be a user group
|
||||
CONSTRAINT [guacamole_user_group_member_parent_id]
|
||||
FOREIGN KEY ([user_group_id])
|
||||
REFERENCES [guacamole_user_group] ([user_group_id])
|
||||
ON DELETE CASCADE,
|
||||
|
||||
-- Member may be either a user or a user group (any entity)
|
||||
CONSTRAINT [guacamole_user_group_member_entity_id]
|
||||
FOREIGN KEY ([member_entity_id])
|
||||
REFERENCES [guacamole_entity] ([entity_id])
|
||||
-- ON DELETE CASCADE handled by guacamole_delete_entity trigger
|
||||
|
||||
);
|
||||
GO
|
||||
|
||||
--
|
||||
-- Table of sharing profiles. Each sharing profile has a name, associated set
|
||||
-- of parameters, and a primary connection. The primary connection is the
|
||||
-- connection that the sharing profile shares, and the parameters dictate the
|
||||
-- restrictions/features which apply to the user joining the connection via the
|
||||
-- sharing profile.
|
||||
--
|
||||
|
||||
CREATE TABLE [guacamole_sharing_profile] (
|
||||
|
||||
[sharing_profile_id] [int] IDENTITY(1,1) NOT NULL,
|
||||
[sharing_profile_name] [nvarchar](128) NOT NULL,
|
||||
[primary_connection_id] [int] NOT NULL,
|
||||
|
||||
CONSTRAINT [PK_guacamole_sharing_profile]
|
||||
PRIMARY KEY CLUSTERED ([sharing_profile_id]),
|
||||
|
||||
CONSTRAINT [AK_guacamole_sharing_profile_name_primary_connection]
|
||||
UNIQUE ([sharing_profile_name], [primary_connection_id]),
|
||||
|
||||
CONSTRAINT [FK_guacamole_sharing_profile_primary_connection_id]
|
||||
FOREIGN KEY ([primary_connection_id])
|
||||
REFERENCES [guacamole_connection] ([connection_id])
|
||||
-- ON DELETE CASCADE handled by guacamole_delete_connection trigger
|
||||
|
||||
);
|
||||
|
||||
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 user group attributes. Each attribute is simply a
|
||||
-- name/value pair associated with a user 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_user_group_attribute] (
|
||||
|
||||
[user_group_id] [int] NOT NULL,
|
||||
[attribute_name] [nvarchar](128) NOT NULL,
|
||||
[attribute_value] [nvarchar](4000) NOT NULL,
|
||||
|
||||
CONSTRAINT [PK_guacamole_user_group_attribute]
|
||||
PRIMARY KEY CLUSTERED ([user_group_id], [attribute_name]),
|
||||
|
||||
CONSTRAINT [FK_guacamole_user_attribute_user_group_id]
|
||||
FOREIGN KEY ([user_group_id])
|
||||
REFERENCES [guacamole_user_group] ([user_group_id])
|
||||
ON DELETE CASCADE
|
||||
|
||||
);
|
||||
|
||||
CREATE NONCLUSTERED INDEX [IX_guacamole_user_group_attribute_user_id]
|
||||
ON [guacamole_user_group_attribute] ([user_group_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.
|
||||
--
|
||||
|
||||
CREATE TABLE [guacamole_connection_parameter] (
|
||||
|
||||
[connection_id] [int] NOT NULL,
|
||||
[parameter_name] [nvarchar](128) NOT NULL,
|
||||
[parameter_value] [nvarchar](4000) NOT NULL,
|
||||
|
||||
CONSTRAINT [PK_guacamole_connection_parameter]
|
||||
PRIMARY KEY CLUSTERED ([connection_id], [parameter_name]),
|
||||
|
||||
CONSTRAINT [FK_guacamole_connection_parameter_connection_id]
|
||||
FOREIGN KEY ([connection_id])
|
||||
REFERENCES [guacamole_connection] ([connection_id])
|
||||
ON DELETE CASCADE
|
||||
|
||||
);
|
||||
|
||||
CREATE NONCLUSTERED INDEX [IX_guacamole_connection_parameter_connection_id]
|
||||
ON [guacamole_connection_parameter] ([connection_id]);
|
||||
GO
|
||||
|
||||
--
|
||||
-- Table of sharing profile parameters. Each parameter is simply
|
||||
-- name/value pair associated with a sharing profile. These parameters dictate
|
||||
-- the restrictions/features which apply to the user joining the associated
|
||||
-- connection via the sharing profile.
|
||||
--
|
||||
|
||||
CREATE TABLE [guacamole_sharing_profile_parameter] (
|
||||
|
||||
[sharing_profile_id] [int] NOT NULL,
|
||||
[parameter_name] [nvarchar](128) NOT NULL,
|
||||
[parameter_value] [nvarchar](4000) NOT NULL,
|
||||
|
||||
CONSTRAINT [PK_guacamole_sharing_profile_parameter]
|
||||
PRIMARY KEY CLUSTERED ([sharing_profile_id], [parameter_name]),
|
||||
|
||||
CONSTRAINT [FK_guacamole_sharing_profile_parameter_connection_id]
|
||||
FOREIGN KEY ([sharing_profile_id])
|
||||
REFERENCES [guacamole_sharing_profile] ([sharing_profile_id])
|
||||
ON DELETE CASCADE
|
||||
|
||||
);
|
||||
|
||||
CREATE NONCLUSTERED INDEX [IX_guacamole_sharing_profile_parameter_sharing_profile_id]
|
||||
ON [guacamole_sharing_profile_parameter] ([sharing_profile_id]);
|
||||
GO
|
||||
|
||||
--
|
||||
-- Table of connection permissions. Each connection permission grants a user or
|
||||
-- user group specific access to a connection.
|
||||
--
|
||||
|
||||
CREATE TABLE [guacamole_connection_permission] (
|
||||
|
||||
[entity_id] [int] NOT NULL,
|
||||
[connection_id] [int] NOT NULL,
|
||||
[permission] [guacamole_object_permission] NOT NULL,
|
||||
|
||||
CONSTRAINT [PK_guacamole_connection_permission]
|
||||
PRIMARY KEY CLUSTERED ([entity_id], [connection_id], [permission]),
|
||||
|
||||
CONSTRAINT [FK_guacamole_connection_permission_connection_id]
|
||||
FOREIGN KEY ([connection_id])
|
||||
REFERENCES [guacamole_connection] ([connection_id])
|
||||
ON DELETE CASCADE,
|
||||
|
||||
CONSTRAINT [FK_guacamole_connection_permission_entity_id]
|
||||
FOREIGN KEY ([entity_id])
|
||||
REFERENCES [guacamole_entity] ([entity_id])
|
||||
ON DELETE CASCADE
|
||||
|
||||
);
|
||||
|
||||
CREATE NONCLUSTERED INDEX [IX_guacamole_connection_permission_connection_id]
|
||||
ON [guacamole_connection_permission] ([connection_id]);
|
||||
|
||||
CREATE NONCLUSTERED INDEX [IX_guacamole_connection_permission_entity_id]
|
||||
ON [guacamole_connection_permission] ([entity_id]);
|
||||
GO
|
||||
|
||||
--
|
||||
-- Table of connection group permissions. Each group permission grants a user
|
||||
-- or user group specific access to a connection group.
|
||||
--
|
||||
|
||||
CREATE TABLE [guacamole_connection_group_permission] (
|
||||
|
||||
[entity_id] [int] NOT NULL,
|
||||
[connection_group_id] [int] NOT NULL,
|
||||
[permission] [guacamole_object_permission] NOT NULL,
|
||||
|
||||
CONSTRAINT [PK_guacamole_connection_group_permission]
|
||||
PRIMARY KEY CLUSTERED ([entity_id], [connection_group_id], [permission]),
|
||||
|
||||
CONSTRAINT [FK_guacamole_connection_group_permission_connection_group_id]
|
||||
FOREIGN KEY ([connection_group_id])
|
||||
REFERENCES [guacamole_connection_group] ([connection_group_id])
|
||||
ON DELETE CASCADE,
|
||||
|
||||
CONSTRAINT [FK_guacamole_connection_group_permission_entity_id]
|
||||
FOREIGN KEY ([entity_id])
|
||||
REFERENCES [guacamole_entity] ([entity_id])
|
||||
ON DELETE CASCADE
|
||||
|
||||
);
|
||||
|
||||
CREATE NONCLUSTERED INDEX [IX_guacamole_connection_group_permission_connection_group_id]
|
||||
ON [guacamole_connection_group_permission] ([connection_group_id]);
|
||||
|
||||
CREATE NONCLUSTERED INDEX [IX_guacamole_connection_group_permission_entity_id]
|
||||
ON [guacamole_connection_group_permission] ([entity_id]);
|
||||
GO
|
||||
|
||||
--
|
||||
-- Table of sharing profile permissions. Each sharing profile permission grants
|
||||
-- a user or user group specific access to a sharing profile.
|
||||
--
|
||||
|
||||
CREATE TABLE [guacamole_sharing_profile_permission] (
|
||||
|
||||
[entity_id] [int] NOT NULL,
|
||||
[sharing_profile_id] [int] NOT NULL,
|
||||
[permission] [guacamole_object_permission] NOT NULL,
|
||||
|
||||
CONSTRAINT [PK_guacamole_sharing_profile_permission]
|
||||
PRIMARY KEY CLUSTERED ([entity_id], [sharing_profile_id], [permission]),
|
||||
|
||||
CONSTRAINT [FK_guacamole_sharing_profile_permission_sharing_profile_id]
|
||||
FOREIGN KEY ([sharing_profile_id])
|
||||
REFERENCES [guacamole_sharing_profile] ([sharing_profile_id])
|
||||
ON DELETE CASCADE,
|
||||
|
||||
CONSTRAINT [FK_guacamole_sharing_profile_permission_entity_id]
|
||||
FOREIGN KEY ([entity_id])
|
||||
REFERENCES [guacamole_entity] ([entity_id])
|
||||
ON DELETE CASCADE
|
||||
|
||||
);
|
||||
|
||||
CREATE NONCLUSTERED INDEX [IX_guacamole_sharing_profile_permission_sharing_profile_id]
|
||||
ON [guacamole_sharing_profile_permission] ([sharing_profile_id]);
|
||||
|
||||
CREATE NONCLUSTERED INDEX [IX_guacamole_sharing_profile_permission_entity_id]
|
||||
ON [guacamole_sharing_profile_permission] ([entity_id]);
|
||||
GO
|
||||
|
||||
--
|
||||
-- Table of system permissions. Each system permission grants a user or user
|
||||
-- group a system-level privilege of some kind.
|
||||
--
|
||||
|
||||
CREATE TABLE [guacamole_system_permission] (
|
||||
|
||||
[entity_id] [int] NOT NULL,
|
||||
[permission] [guacamole_system_permission] NOT NULL,
|
||||
|
||||
CONSTRAINT [PK_guacamole_system_permission]
|
||||
PRIMARY KEY CLUSTERED ([entity_id], [permission]),
|
||||
|
||||
CONSTRAINT [FK_guacamole_system_permission_entity_id]
|
||||
FOREIGN KEY ([entity_id])
|
||||
REFERENCES [guacamole_entity] ([entity_id])
|
||||
ON DELETE CASCADE
|
||||
|
||||
);
|
||||
|
||||
CREATE NONCLUSTERED INDEX [IX_guacamole_system_permission_entity_id]
|
||||
ON [guacamole_system_permission] ([entity_id]);
|
||||
GO
|
||||
|
||||
--
|
||||
-- Table of user permissions. Each user permission grants a user or user group
|
||||
-- access to another user (the "affected" user) for a specific type of
|
||||
-- operation.
|
||||
--
|
||||
|
||||
CREATE TABLE [guacamole_user_permission] (
|
||||
|
||||
[entity_id] [int] NOT NULL,
|
||||
[affected_user_id] [int] NOT NULL,
|
||||
[permission] [guacamole_object_permission] NOT NULL,
|
||||
|
||||
CONSTRAINT [PK_guacamole_user_permission]
|
||||
PRIMARY KEY CLUSTERED ([entity_id], [affected_user_id], [permission]),
|
||||
|
||||
CONSTRAINT [FK_guacamole_user_permission_affected_user_id]
|
||||
FOREIGN KEY ([affected_user_id])
|
||||
REFERENCES [guacamole_user] ([user_id])
|
||||
ON DELETE CASCADE,
|
||||
|
||||
CONSTRAINT [FK_guacamole_user_permission_entity_id]
|
||||
FOREIGN KEY ([entity_id])
|
||||
REFERENCES [guacamole_entity] ([entity_id])
|
||||
-- ON DELETE CASCADE handled by guacamole_delete_entity trigger
|
||||
|
||||
);
|
||||
|
||||
CREATE NONCLUSTERED INDEX [IX_guacamole_user_permission_entity_id]
|
||||
ON [guacamole_user_permission] ([entity_id]);
|
||||
|
||||
CREATE NONCLUSTERED INDEX [IX_guacamole_user_permission_affected_user_id]
|
||||
ON [guacamole_user_permission] ([affected_user_id]);
|
||||
GO
|
||||
|
||||
--
|
||||
-- Table of user group permissions. Each user group permission grants a user
|
||||
-- or user group access to a another user group (the "affected" user group) for
|
||||
-- a specific type of operation.
|
||||
--
|
||||
|
||||
CREATE TABLE [guacamole_user_group_permission] (
|
||||
|
||||
[entity_id] [int] NOT NULL,
|
||||
[affected_user_group_id] [int] NOT NULL,
|
||||
[permission] [guacamole_object_permission] NOT NULL,
|
||||
|
||||
CONSTRAINT [PK_guacamole_user_group_permission]
|
||||
PRIMARY KEY CLUSTERED ([entity_id], [affected_user_group_id], [permission]),
|
||||
|
||||
CONSTRAINT [FK_guacamole_user_group_permission_affected_user_group_id]
|
||||
FOREIGN KEY ([affected_user_group_id])
|
||||
REFERENCES [guacamole_user_group] ([user_group_id])
|
||||
ON DELETE CASCADE,
|
||||
|
||||
CONSTRAINT [FK_guacamole_user_group_permission_entity_id]
|
||||
FOREIGN KEY ([entity_id])
|
||||
REFERENCES [guacamole_entity] ([entity_id])
|
||||
-- ON DELETE CASCADE handled by guacamole_delete_entity trigger
|
||||
|
||||
);
|
||||
|
||||
CREATE NONCLUSTERED INDEX [IX_guacamole_user_group_permission_entity_id]
|
||||
ON [guacamole_user_group_permission] ([entity_id]);
|
||||
|
||||
CREATE NONCLUSTERED INDEX [IX_guacamole_user_group_permission_affected_user_group_id]
|
||||
ON [guacamole_user_group_permission] ([affected_user_group_id]);
|
||||
GO
|
||||
|
||||
--
|
||||
-- Table of connection history records. Each record defines a specific user's
|
||||
-- session, including the connection used, the start time, and the end time
|
||||
-- (if any).
|
||||
--
|
||||
|
||||
CREATE TABLE [guacamole_connection_history] (
|
||||
|
||||
[history_id] [int] IDENTITY(1,1) NOT NULL,
|
||||
[user_id] [int],
|
||||
[username] [nvarchar](128) NOT NULL,
|
||||
[remote_host] [nvarchar](256),
|
||||
[connection_id] [int],
|
||||
[connection_name] [nvarchar](128) NOT NULL,
|
||||
[sharing_profile_id] [int],
|
||||
[sharing_profile_name] [nvarchar](128),
|
||||
[start_date] [datetime] NOT NULL,
|
||||
[end_date] [datetime],
|
||||
|
||||
CONSTRAINT [PK_guacamole_connection_history]
|
||||
PRIMARY KEY CLUSTERED ([history_id]),
|
||||
|
||||
CONSTRAINT [FK_guacamole_connection_history_user_id]
|
||||
FOREIGN KEY ([user_id])
|
||||
REFERENCES [guacamole_user] ([user_id])
|
||||
ON DELETE SET NULL,
|
||||
|
||||
CONSTRAINT [FK_guacamole_connection_history_connection_id]
|
||||
FOREIGN KEY ([connection_id])
|
||||
REFERENCES [guacamole_connection] ([connection_id])
|
||||
ON DELETE SET NULL,
|
||||
|
||||
CONSTRAINT [FK_guacamole_connection_history_sharing_profile_id]
|
||||
FOREIGN KEY ([sharing_profile_id])
|
||||
REFERENCES [guacamole_sharing_profile] ([sharing_profile_id])
|
||||
-- ON DELETE SET NULL handled by guacamole_delete_sharing profile trigger
|
||||
|
||||
);
|
||||
|
||||
CREATE NONCLUSTERED INDEX [IX_guacamole_connection_history_user_id]
|
||||
ON [guacamole_connection_history] ([user_id]);
|
||||
|
||||
CREATE NONCLUSTERED INDEX [IX_guacamole_connection_history_connection_id]
|
||||
ON [guacamole_connection_history] ([connection_id]);
|
||||
|
||||
CREATE NONCLUSTERED INDEX [IX_guacamole_connection_history_sharing_profile_id]
|
||||
ON [guacamole_connection_history] ([sharing_profile_id]);
|
||||
|
||||
CREATE NONCLUSTERED INDEX [IX_guacamole_connection_history_start_date]
|
||||
ON [guacamole_connection_history] ([start_date]);
|
||||
|
||||
CREATE NONCLUSTERED INDEX [IX_guacamole_connection_history_end_date]
|
||||
ON [guacamole_connection_history] ([end_date]);
|
||||
|
||||
CREATE NONCLUSTERED INDEX [IX_guacamole_connection_history_connection_id_start_date]
|
||||
ON [guacamole_connection_history] ([connection_id], [start_date]);
|
||||
GO
|
||||
|
||||
--
|
||||
-- User login/logout history
|
||||
--
|
||||
|
||||
CREATE TABLE [guacamole_user_history] (
|
||||
|
||||
[history_id] [int] IDENTITY(1,1) NOT NULL,
|
||||
[user_id] [int] DEFAULT NULL,
|
||||
[username] [nvarchar](128) NOT NULL,
|
||||
[remote_host] [nvarchar](256) DEFAULT NULL,
|
||||
[start_date] [datetime] NOT NULL,
|
||||
[end_date] [datetime] DEFAULT NULL,
|
||||
|
||||
PRIMARY KEY (history_id),
|
||||
|
||||
CONSTRAINT FK_guacamole_user_history_user_id
|
||||
FOREIGN KEY (user_id)
|
||||
REFERENCES guacamole_user (user_id) ON DELETE SET NULL
|
||||
|
||||
);
|
||||
|
||||
CREATE NONCLUSTERED INDEX [IX_guacamole_user_history_user_id]
|
||||
ON [guacamole_user_history] ([user_id]);
|
||||
|
||||
CREATE NONCLUSTERED INDEX [IX_guacamole_user_history_start_date]
|
||||
ON [guacamole_user_history] ([start_date]);
|
||||
|
||||
CREATE NONCLUSTERED INDEX [IX_guacamole_user_history_end_date]
|
||||
ON [guacamole_user_history] ([end_date]);
|
||||
|
||||
CREATE NONCLUSTERED INDEX [IX_guacamole_user_history_user_id_start_date]
|
||||
ON [guacamole_user_history] ([user_id], [start_date]);
|
||||
GO
|
||||
|
||||
--
|
||||
-- The user_password_history table stores password history
|
||||
-- for users, allowing for enforcing rules associated with
|
||||
-- reuse of passwords.
|
||||
--
|
||||
|
||||
CREATE TABLE [guacamole_user_password_history] (
|
||||
|
||||
[password_history_id] [int] IDENTITY(1,1) NOT NULL,
|
||||
[user_id] [int] NOT NULL,
|
||||
|
||||
-- Salted password
|
||||
[password_hash] [binary](32) NOT NULL,
|
||||
[password_salt] [binary](32),
|
||||
[password_date] [datetime] NOT NULL,
|
||||
|
||||
CONSTRAINT [PK_guacamole_user_password_history]
|
||||
PRIMARY KEY CLUSTERED ([password_history_id]),
|
||||
|
||||
CONSTRAINT [FK_guacamole_user_password_history_user_id]
|
||||
FOREIGN KEY ([user_id])
|
||||
REFERENCES [guacamole_user] ([user_id])
|
||||
ON DELETE CASCADE
|
||||
|
||||
);
|
||||
|
||||
CREATE NONCLUSTERED INDEX [IX_guacamole_user_password_history_user_id]
|
||||
ON [guacamole_user_password_history] ([user_id]);
|
||||
GO
|
||||
|
||||
--
|
||||
-- Handle cascading deletion/updates of records in response to deletion of
|
||||
-- guacamole_entity records, where such deletion is not already covered by
|
||||
-- ON DELETE CASCADE or ON DELETE SET NULL.
|
||||
--
|
||||
|
||||
CREATE TRIGGER [guacamole_delete_entity]
|
||||
ON [guacamole_entity]
|
||||
INSTEAD OF DELETE
|
||||
AS BEGIN
|
||||
|
||||
-- Do not take trigger into account when producing row counts for the DELETE
|
||||
SET NOCOUNT ON;
|
||||
|
||||
-- Delete all associated permissions not covered by ON DELETE CASCADE
|
||||
DELETE FROM [guacamole_user_permission]
|
||||
WHERE [entity_id] IN (SELECT [entity_id] FROM DELETED);
|
||||
|
||||
DELETE FROM [guacamole_user_group_permission]
|
||||
WHERE [entity_id] IN (SELECT [entity_id] FROM DELETED);
|
||||
|
||||
-- Delete all associated group memberships not covered by ON DELETE CASCADE
|
||||
DELETE FROM [guacamole_user_group_member]
|
||||
WHERE [member_entity_id] IN (SELECT [entity_id] FROM DELETED);
|
||||
|
||||
-- Perform original deletion
|
||||
DELETE FROM [guacamole_entity]
|
||||
WHERE [entity_id] IN (SELECT [entity_id] FROM DELETED);
|
||||
|
||||
END
|
||||
GO
|
||||
|
||||
--
|
||||
-- Handle cascading deletion/updates of records in response to deletion of
|
||||
-- guacamole_connection records, where such deletion is not already covered by
|
||||
-- ON DELETE CASCADE or ON DELETE SET NULL.
|
||||
--
|
||||
|
||||
CREATE TRIGGER [guacamole_delete_connection]
|
||||
ON [guacamole_connection]
|
||||
INSTEAD OF DELETE
|
||||
AS BEGIN
|
||||
|
||||
-- Do not take trigger into account when producing row counts for the DELETE
|
||||
SET NOCOUNT ON;
|
||||
|
||||
-- Delete associated sharing profiles
|
||||
DELETE FROM [guacamole_sharing_profile]
|
||||
WHERE [primary_connection_id] IN (SELECT [connection_id] FROM DELETED);
|
||||
|
||||
-- Perform original deletion
|
||||
DELETE FROM [guacamole_connection]
|
||||
WHERE [connection_id] IN (SELECT [connection_id] FROM DELETED);
|
||||
|
||||
END
|
||||
GO
|
||||
|
||||
--
|
||||
-- Handle cascading deletion/updates of records in response to deletion of
|
||||
-- guacamole_connection_group records, where such deletion is not already
|
||||
-- covered by ON DELETE CASCADE or ON DELETE SET NULL.
|
||||
--
|
||||
|
||||
CREATE TRIGGER [guacamole_delete_connection_group]
|
||||
ON [guacamole_connection_group]
|
||||
INSTEAD OF DELETE
|
||||
AS BEGIN
|
||||
|
||||
-- Do not take trigger into account when producing row counts for the DELETE
|
||||
SET NOCOUNT ON;
|
||||
|
||||
-- Delete all descendant connections
|
||||
WITH [connection_groups] ([connection_group_id]) AS (
|
||||
SELECT [connection_group_id] FROM DELETED
|
||||
UNION ALL
|
||||
SELECT [guacamole_connection_group].[connection_group_id]
|
||||
FROM [guacamole_connection_group]
|
||||
JOIN [connection_groups] ON [connection_groups].[connection_group_id] = [guacamole_connection_group].[parent_id]
|
||||
)
|
||||
DELETE FROM [guacamole_connection]
|
||||
WHERE [parent_id] IN (
|
||||
SELECT [connection_group_id]
|
||||
FROM [connection_groups]
|
||||
);
|
||||
|
||||
-- Delete all requested connection groups, including descendants
|
||||
WITH [connection_groups] ([connection_group_id]) AS (
|
||||
SELECT [connection_group_id] FROM DELETED
|
||||
UNION ALL
|
||||
SELECT [guacamole_connection_group].[connection_group_id]
|
||||
FROM [guacamole_connection_group]
|
||||
JOIN [connection_groups] ON [connection_groups].[connection_group_id] = [guacamole_connection_group].[parent_id]
|
||||
)
|
||||
DELETE FROM [guacamole_connection_group]
|
||||
WHERE [connection_group_id] IN (
|
||||
SELECT [connection_group_id]
|
||||
FROM [connection_groups]
|
||||
);
|
||||
|
||||
END
|
||||
GO
|
||||
|
||||
--
|
||||
-- Handle cascading deletion/updates of records in response to deletion of
|
||||
-- guacamole_sharing_profile records, where such deletion is not already
|
||||
-- covered by ON DELETE CASCADE or ON DELETE SET NULL.
|
||||
--
|
||||
|
||||
CREATE TRIGGER [guacamole_delete_sharing_profile]
|
||||
ON [guacamole_sharing_profile]
|
||||
INSTEAD OF DELETE
|
||||
AS BEGIN
|
||||
|
||||
-- Do not take trigger into account when producing row counts for the DELETE
|
||||
SET NOCOUNT ON;
|
||||
|
||||
-- Delete all associated permissions not covered by ON DELETE CASCADE
|
||||
UPDATE [guacamole_connection_history]
|
||||
SET [sharing_profile_id] = NULL
|
||||
WHERE [sharing_profile_id] IN (SELECT [sharing_profile_id] FROM DELETED);
|
||||
|
||||
-- Perform original deletion
|
||||
DELETE FROM [guacamole_sharing_profile]
|
||||
WHERE [sharing_profile_id] IN (SELECT [sharing_profile_id] FROM DELETED);
|
||||
|
||||
END
|
||||
GO
|
||||
|
@@ -0,0 +1,64 @@
|
||||
--
|
||||
-- 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.
|
||||
--
|
||||
|
||||
-- Create default user "guacadmin" with password "guacadmin"
|
||||
INSERT INTO [guacamole_entity] ([name], [type]) VALUES ('guacadmin', 'USER');
|
||||
INSERT INTO [guacamole_user] (
|
||||
[entity_id],
|
||||
[password_hash],
|
||||
[password_salt],
|
||||
[password_date]
|
||||
)
|
||||
SELECT
|
||||
[entity_id],
|
||||
0xCA458A7D494E3BE824F5E1E175A1556C0F8EEF2C2D7DF3633BEC4A29C4411960,
|
||||
0xFE24ADC5E11E2B25288D1704ABE67A79E342ECC26064CE69C5B3177795A82264,
|
||||
getdate()
|
||||
FROM [guacamole_entity] WHERE [name] = 'guacadmin';
|
||||
|
||||
-- Grant this user all system permissions
|
||||
INSERT INTO [guacamole_system_permission]
|
||||
SELECT
|
||||
[entity_id],
|
||||
[permission]
|
||||
FROM (
|
||||
SELECT 'guacadmin', 'CREATE_CONNECTION'
|
||||
UNION SELECT 'guacadmin', 'CREATE_CONNECTION_GROUP'
|
||||
UNION SELECT 'guacadmin', 'CREATE_SHARING_PROFILE'
|
||||
UNION SELECT 'guacadmin', 'CREATE_USER'
|
||||
UNION SELECT 'guacadmin', 'CREATE_USER_GROUP'
|
||||
UNION SELECT 'guacadmin', 'ADMINISTER'
|
||||
) [permissions] ([username], [permission])
|
||||
JOIN [guacamole_entity] ON [permissions].[username] = [guacamole_entity].[name] AND [guacamole_entity].[type] = 'USER';
|
||||
|
||||
INSERT INTO [guacamole_user_permission]
|
||||
SELECT
|
||||
[guacamole_entity].[entity_id],
|
||||
[guacamole_user].[user_id],
|
||||
[permission]
|
||||
FROM (
|
||||
SELECT 'guacadmin', 'guacadmin', 'READ'
|
||||
UNION SELECT 'guacadmin', 'guacadmin', 'UPDATE'
|
||||
UNION SELECT 'guacadmin', 'guacadmin', 'ADMINISTER'
|
||||
) [permissions] ([username], [affected_username], [permission])
|
||||
JOIN [guacamole_entity] ON [permissions].[username] = [guacamole_entity].[name] AND [guacamole_entity].[type] = 'USER'
|
||||
JOIN [guacamole_entity] [affected] ON [permissions].[affected_username] = [affected].[name] AND [guacamole_entity].[type] = 'USER'
|
||||
JOIN [guacamole_user] ON [guacamole_user].[entity_id] = [affected].[entity_id];
|
||||
GO
|
||||
|
@@ -0,0 +1,659 @@
|
||||
--
|
||||
-- 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.
|
||||
--
|
||||
|
||||
--
|
||||
-- Add new system-level permission
|
||||
--
|
||||
|
||||
EXEC sp_unbindrule 'guacamole_system_permission';
|
||||
DROP RULE [guacamole_system_permission_list];
|
||||
GO
|
||||
|
||||
CREATE RULE [guacamole_system_permission_list] AS @list IN (
|
||||
'CREATE_CONNECTION',
|
||||
'CREATE_CONNECTION_GROUP',
|
||||
'CREATE_SHARING_PROFILE',
|
||||
'CREATE_USER',
|
||||
'CREATE_USER_GROUP',
|
||||
'ADMINISTER'
|
||||
);
|
||||
GO
|
||||
|
||||
EXEC sp_bindrule
|
||||
'guacamole_system_permission_list',
|
||||
'guacamole_system_permission';
|
||||
GO
|
||||
|
||||
--
|
||||
-- Entity types
|
||||
--
|
||||
|
||||
CREATE RULE [guacamole_entity_type_list] AS @list IN (
|
||||
'USER',
|
||||
'USER_GROUP'
|
||||
);
|
||||
GO
|
||||
|
||||
CREATE TYPE [guacamole_entity_type] FROM [nvarchar](16);
|
||||
EXEC sp_bindrule
|
||||
'guacamole_entity_type_list',
|
||||
'guacamole_entity_type';
|
||||
GO
|
||||
|
||||
--
|
||||
-- Table of base entities which may each be either a user or user group. Other
|
||||
-- tables which represent qualities shared by both users and groups will point
|
||||
-- to guacamole_entity, while tables which represent qualities specific to
|
||||
-- users or groups will point to guacamole_user or guacamole_user_group.
|
||||
--
|
||||
|
||||
CREATE TABLE [guacamole_entity] (
|
||||
|
||||
[entity_id] [int] IDENTITY(1,1) NOT NULL,
|
||||
[name] [nvarchar](128) NOT NULL,
|
||||
[type] [guacamole_entity_type] NOT NULL,
|
||||
|
||||
CONSTRAINT [PK_guacamole_entity]
|
||||
PRIMARY KEY CLUSTERED ([entity_id]),
|
||||
|
||||
CONSTRAINT [AK_guacamole_entity_name_scope]
|
||||
UNIQUE ([type], [name])
|
||||
|
||||
);
|
||||
GO
|
||||
|
||||
--
|
||||
-- Table of user groups. Each user group may have an arbitrary set of member
|
||||
-- users and member groups, with those members inheriting the permissions
|
||||
-- granted to that group.
|
||||
--
|
||||
|
||||
CREATE TABLE [guacamole_user_group] (
|
||||
|
||||
[user_group_id] [int] IDENTITY(1,1) NOT NULL,
|
||||
[entity_id] [int] NOT NULL,
|
||||
|
||||
-- Group disabled status
|
||||
[disabled] [bit] NOT NULL DEFAULT 0,
|
||||
|
||||
CONSTRAINT [PK_guacamole_user_group]
|
||||
PRIMARY KEY CLUSTERED ([user_group_id]),
|
||||
|
||||
CONSTRAINT [guacamole_user_group_single_entity]
|
||||
UNIQUE ([entity_id]),
|
||||
|
||||
CONSTRAINT [guacamole_user_group_entity]
|
||||
FOREIGN KEY ([entity_id])
|
||||
REFERENCES [guacamole_entity] ([entity_id])
|
||||
ON DELETE CASCADE
|
||||
|
||||
);
|
||||
GO
|
||||
|
||||
--
|
||||
-- Table of users which are members of given user groups.
|
||||
--
|
||||
|
||||
CREATE TABLE [guacamole_user_group_member] (
|
||||
|
||||
[user_group_id] [int] NOT NULL,
|
||||
[member_entity_id] [int] NOT NULL,
|
||||
|
||||
CONSTRAINT [PK_guacamole_user_group_member]
|
||||
PRIMARY KEY CLUSTERED ([user_group_id], [member_entity_id]),
|
||||
|
||||
-- Parent must be a user group
|
||||
CONSTRAINT [guacamole_user_group_member_parent_id]
|
||||
FOREIGN KEY ([user_group_id])
|
||||
REFERENCES [guacamole_user_group] ([user_group_id])
|
||||
ON DELETE CASCADE,
|
||||
|
||||
-- Member may be either a user or a user group (any entity)
|
||||
CONSTRAINT [guacamole_user_group_member_entity_id]
|
||||
FOREIGN KEY ([member_entity_id])
|
||||
REFERENCES [guacamole_entity] ([entity_id])
|
||||
-- ON DELETE CASCADE handled by guacamole_delete_entity trigger
|
||||
|
||||
);
|
||||
GO
|
||||
|
||||
--
|
||||
-- Table of user group permissions. Each user group permission grants a user
|
||||
-- or user group access to a another user group (the "affected" user group) for
|
||||
-- a specific type of operation.
|
||||
--
|
||||
|
||||
CREATE TABLE [guacamole_user_group_permission] (
|
||||
|
||||
[entity_id] [int] NOT NULL,
|
||||
[affected_user_group_id] [int] NOT NULL,
|
||||
[permission] [guacamole_object_permission] NOT NULL,
|
||||
|
||||
CONSTRAINT [PK_guacamole_user_group_permission]
|
||||
PRIMARY KEY CLUSTERED ([entity_id], [affected_user_group_id], [permission]),
|
||||
|
||||
CONSTRAINT [FK_guacamole_user_group_permission_affected_user_group_id]
|
||||
FOREIGN KEY ([affected_user_group_id])
|
||||
REFERENCES [guacamole_user_group] ([user_group_id])
|
||||
ON DELETE CASCADE,
|
||||
|
||||
CONSTRAINT [FK_guacamole_user_group_permission_entity_id]
|
||||
FOREIGN KEY ([entity_id])
|
||||
REFERENCES [guacamole_entity] ([entity_id])
|
||||
-- ON DELETE CASCADE handled by guacamole_delete_entity trigger
|
||||
|
||||
);
|
||||
|
||||
CREATE NONCLUSTERED INDEX [IX_guacamole_user_group_permission_entity_id]
|
||||
ON [guacamole_user_group_permission] ([entity_id]);
|
||||
|
||||
CREATE NONCLUSTERED INDEX [IX_guacamole_user_group_permission_affected_user_group_id]
|
||||
ON [guacamole_user_group_permission] ([affected_user_group_id]);
|
||||
GO
|
||||
|
||||
--
|
||||
-- The guacamole_delete_entity trigger effectively replaces the
|
||||
-- guacamole_delete_user trigger, which is no longer necessary and will cease
|
||||
-- being correct after the columns of existing tables are updated.
|
||||
--
|
||||
|
||||
DROP TRIGGER [guacamole_delete_user];
|
||||
GO
|
||||
|
||||
--
|
||||
-- Modify guacamole_user table to use guacamole_entity as a base
|
||||
--
|
||||
|
||||
-- Add new entity_id column
|
||||
ALTER TABLE [guacamole_user] ADD [entity_id] [int];
|
||||
GO
|
||||
|
||||
-- Create user entities for each guacamole_user entry
|
||||
INSERT INTO [guacamole_entity] ([name], [type])
|
||||
SELECT [username], 'USER' FROM [guacamole_user];
|
||||
GO
|
||||
|
||||
-- Update guacamole_user to point to corresponding guacamole_entity
|
||||
UPDATE [guacamole_user] SET [entity_id] = (
|
||||
SELECT [entity_id] FROM [guacamole_entity]
|
||||
WHERE
|
||||
[username] = [guacamole_entity].[name]
|
||||
AND type = 'USER'
|
||||
);
|
||||
GO
|
||||
|
||||
-- The entity_id column should now be safely non-NULL
|
||||
ALTER TABLE [guacamole_user]
|
||||
ALTER COLUMN [entity_id] [int] NOT NULL;
|
||||
|
||||
-- The entity_id column should now be unique for each user
|
||||
ALTER TABLE [guacamole_user]
|
||||
ADD CONSTRAINT [AK_guacamole_user_single_entity]
|
||||
UNIQUE ([entity_id]);
|
||||
|
||||
-- The entity_id column should now safely point to guacamole_entity entries
|
||||
ALTER TABLE [guacamole_user]
|
||||
ADD CONSTRAINT [FK_guacamole_user_entity]
|
||||
FOREIGN KEY ([entity_id])
|
||||
REFERENCES [guacamole_entity] ([entity_id])
|
||||
ON DELETE CASCADE;
|
||||
|
||||
-- The username column can now safely be removed
|
||||
ALTER TABLE [guacamole_user] DROP [AK_guacamole_user_username];
|
||||
ALTER TABLE [guacamole_user] DROP COLUMN [username];
|
||||
GO
|
||||
|
||||
--
|
||||
-- Modify guacamole_connection_permission to use guacamole_entity instead of
|
||||
-- guacamole_user
|
||||
--
|
||||
|
||||
-- Add new entity_id column
|
||||
ALTER TABLE [guacamole_connection_permission] ADD [entity_id] [int];
|
||||
GO
|
||||
|
||||
-- Update guacamole_connection_permission to point to the guacamole_entity
|
||||
-- that has been granted the permission
|
||||
UPDATE [guacamole_connection_permission] SET [entity_id] = (
|
||||
SELECT [entity_id] FROM [guacamole_user]
|
||||
WHERE [guacamole_user].[user_id] = [guacamole_connection_permission].[user_id]
|
||||
);
|
||||
GO
|
||||
|
||||
-- The entity_id column should now be safely non-NULL
|
||||
ALTER TABLE [guacamole_connection_permission]
|
||||
ALTER COLUMN [entity_id] [int] NOT NULL;
|
||||
|
||||
-- Remove user_id column
|
||||
DROP INDEX [IX_guacamole_connection_permission_user_id] ON [guacamole_connection_permission];
|
||||
ALTER TABLE [guacamole_connection_permission] DROP [PK_guacamole_connection_permission];
|
||||
ALTER TABLE [guacamole_connection_permission] DROP [FK_guacamole_connection_permission_user_id];
|
||||
ALTER TABLE [guacamole_connection_permission] DROP COLUMN [user_id];
|
||||
|
||||
-- The entity_id column should now safely point to guacamole_entity entries
|
||||
ALTER TABLE [guacamole_connection_permission]
|
||||
ADD CONSTRAINT [FK_guacamole_connection_permission_entity_id]
|
||||
FOREIGN KEY ([entity_id])
|
||||
REFERENCES [guacamole_entity] ([entity_id])
|
||||
ON DELETE CASCADE;
|
||||
|
||||
CREATE NONCLUSTERED INDEX [IX_guacamole_connection_permission_entity_id]
|
||||
ON [guacamole_connection_permission] ([entity_id]);
|
||||
|
||||
-- Add new primary key which uses entity_id
|
||||
ALTER TABLE [guacamole_connection_permission]
|
||||
ADD CONSTRAINT [PK_guacamole_connection_permission]
|
||||
PRIMARY KEY CLUSTERED ([entity_id], [connection_id], [permission]);
|
||||
GO
|
||||
|
||||
--
|
||||
-- Modify guacamole_connection_group_permission to use guacamole_entity instead
|
||||
-- of guacamole_user
|
||||
--
|
||||
|
||||
-- Add new entity_id column
|
||||
ALTER TABLE [guacamole_connection_group_permission] ADD [entity_id] [int];
|
||||
GO
|
||||
|
||||
-- Update guacamole_connection_group_permission to point to the guacamole_entity
|
||||
-- that has been granted the permission
|
||||
UPDATE guacamole_connection_group_permission SET entity_id = (
|
||||
SELECT entity_id FROM guacamole_user
|
||||
WHERE guacamole_user.user_id = guacamole_connection_group_permission.user_id
|
||||
);
|
||||
GO
|
||||
|
||||
-- The entity_id column should now be safely non-NULL
|
||||
ALTER TABLE [guacamole_connection_group_permission]
|
||||
ALTER COLUMN [entity_id] [int] NOT NULL;
|
||||
|
||||
-- Remove user_id column
|
||||
DROP INDEX [IX_guacamole_connection_group_permission_user_id] ON [guacamole_connection_group_permission];
|
||||
ALTER TABLE [guacamole_connection_group_permission] DROP [PK_guacamole_connection_group_permission];
|
||||
ALTER TABLE [guacamole_connection_group_permission] DROP [FK_guacamole_connection_group_permission_user_id];
|
||||
ALTER TABLE [guacamole_connection_group_permission] DROP COLUMN user_id;
|
||||
|
||||
-- The entity_id column should now safely point to guacamole_entity entries
|
||||
ALTER TABLE [guacamole_connection_group_permission]
|
||||
ADD CONSTRAINT [FK_guacamole_connection_group_permission_entity_id]
|
||||
FOREIGN KEY ([entity_id])
|
||||
REFERENCES [guacamole_entity] ([entity_id])
|
||||
ON DELETE CASCADE;
|
||||
|
||||
CREATE NONCLUSTERED INDEX [IX_guacamole_connection_group_permission_entity_id]
|
||||
ON [guacamole_connection_group_permission] ([entity_id]);
|
||||
|
||||
-- Add new primary key which uses entity_id
|
||||
ALTER TABLE [guacamole_connection_group_permission]
|
||||
ADD CONSTRAINT [PK_guacamole_connection_group_permission]
|
||||
PRIMARY KEY CLUSTERED ([entity_id], [connection_group_id], [permission]);
|
||||
GO
|
||||
|
||||
--
|
||||
-- Modify guacamole_sharing_profile_permission to use guacamole_entity instead
|
||||
-- of guacamole_user
|
||||
--
|
||||
|
||||
-- Add new entity_id column
|
||||
ALTER TABLE [guacamole_sharing_profile_permission] ADD [entity_id] [int];
|
||||
GO
|
||||
|
||||
-- Update guacamole_sharing_profile_permission to point to the guacamole_entity
|
||||
-- that has been granted the permission
|
||||
UPDATE guacamole_sharing_profile_permission SET entity_id = (
|
||||
SELECT entity_id FROM guacamole_user
|
||||
WHERE guacamole_user.user_id = guacamole_sharing_profile_permission.user_id
|
||||
);
|
||||
GO
|
||||
|
||||
-- The entity_id column should now be safely non-NULL
|
||||
ALTER TABLE [guacamole_sharing_profile_permission]
|
||||
ALTER COLUMN [entity_id] [int] NOT NULL;
|
||||
|
||||
-- Remove user_id column
|
||||
DROP INDEX [IX_guacamole_sharing_profile_permission_user_id] ON [guacamole_sharing_profile_permission];
|
||||
ALTER TABLE [guacamole_sharing_profile_permission] DROP [PK_guacamole_sharing_profile_permission];
|
||||
ALTER TABLE [guacamole_sharing_profile_permission] DROP [FK_guacamole_sharing_profile_permission_user_id];
|
||||
ALTER TABLE [guacamole_sharing_profile_permission] DROP COLUMN user_id;
|
||||
|
||||
-- The entity_id column should now safely point to guacamole_entity entries
|
||||
ALTER TABLE [guacamole_sharing_profile_permission]
|
||||
ADD CONSTRAINT [FK_guacamole_sharing_profile_permission_entity_id]
|
||||
FOREIGN KEY ([entity_id])
|
||||
REFERENCES [guacamole_entity] ([entity_id])
|
||||
ON DELETE CASCADE;
|
||||
|
||||
CREATE NONCLUSTERED INDEX [IX_guacamole_sharing_profile_permission_entity_id]
|
||||
ON [guacamole_sharing_profile_permission] ([entity_id]);
|
||||
|
||||
-- Add new primary key which uses entity_id
|
||||
ALTER TABLE [guacamole_sharing_profile_permission]
|
||||
ADD CONSTRAINT [PK_guacamole_sharing_profile_permission]
|
||||
PRIMARY KEY CLUSTERED ([entity_id], [sharing_profile_id], [permission]);
|
||||
GO
|
||||
|
||||
--
|
||||
-- Modify guacamole_user_permission to use guacamole_entity instead of
|
||||
-- guacamole_user
|
||||
--
|
||||
|
||||
-- Add new entity_id column
|
||||
ALTER TABLE [guacamole_user_permission] ADD [entity_id] [int];
|
||||
GO
|
||||
|
||||
-- Update guacamole_user_permission to point to the guacamole_entity
|
||||
-- that has been granted the permission
|
||||
UPDATE guacamole_user_permission SET entity_id = (
|
||||
SELECT entity_id FROM guacamole_user
|
||||
WHERE guacamole_user.user_id = guacamole_user_permission.user_id
|
||||
);
|
||||
GO
|
||||
|
||||
-- The entity_id column should now be safely non-NULL
|
||||
ALTER TABLE [guacamole_user_permission]
|
||||
ALTER COLUMN [entity_id] [int] NOT NULL;
|
||||
|
||||
-- The entity_id column should now safely point to guacamole_entity entries
|
||||
ALTER TABLE [guacamole_user_permission]
|
||||
ADD CONSTRAINT [FK_guacamole_user_permission_entity_id]
|
||||
FOREIGN KEY ([entity_id])
|
||||
REFERENCES [guacamole_entity] ([entity_id]);
|
||||
-- ON DELETE CASCADE handled by guacamole_delete_entity trigger
|
||||
|
||||
-- The affected_user_id column now has ON DELETE CASCADE
|
||||
ALTER TABLE [guacamole_user_permission] DROP [FK_guacamole_user_permission_affected_user_id];
|
||||
ALTER TABLE [guacamole_user_permission]
|
||||
ADD CONSTRAINT [FK_guacamole_user_permission_affected_user_id]
|
||||
FOREIGN KEY ([affected_user_id])
|
||||
REFERENCES [guacamole_user] ([user_id])
|
||||
ON DELETE CASCADE;
|
||||
|
||||
CREATE NONCLUSTERED INDEX [IX_guacamole_user_permission_entity_id]
|
||||
ON [guacamole_user_permission] ([entity_id]);
|
||||
|
||||
-- Remove user_id column
|
||||
DROP INDEX [IX_guacamole_user_permission_user_id] ON [guacamole_user_permission];
|
||||
ALTER TABLE [guacamole_user_permission] DROP [PK_guacamole_user_permission];
|
||||
ALTER TABLE [guacamole_user_permission] DROP [FK_guacamole_user_permission_user_id];
|
||||
ALTER TABLE [guacamole_user_permission] DROP COLUMN user_id;
|
||||
|
||||
-- Add new primary key which uses entity_id
|
||||
ALTER TABLE [guacamole_user_permission]
|
||||
ADD CONSTRAINT [PK_guacamole_user_permission]
|
||||
PRIMARY KEY CLUSTERED ([entity_id], [affected_user_id], [permission]);
|
||||
GO
|
||||
|
||||
--
|
||||
-- Modify guacamole_system_permission to use guacamole_entity instead of
|
||||
-- guacamole_user
|
||||
--
|
||||
|
||||
-- Add new entity_id column
|
||||
ALTER TABLE [guacamole_system_permission] ADD [entity_id] [int];
|
||||
GO
|
||||
|
||||
-- Update guacamole_system_permission to point to the guacamole_entity
|
||||
-- that has been granted the permission
|
||||
UPDATE [guacamole_system_permission] SET [entity_id] = (
|
||||
SELECT [entity_id] FROM [guacamole_user]
|
||||
WHERE [guacamole_user].[user_id] = [guacamole_system_permission].[user_id]
|
||||
);
|
||||
GO
|
||||
|
||||
-- The entity_id column should now be safely non-NULL
|
||||
ALTER TABLE [guacamole_system_permission]
|
||||
ALTER COLUMN [entity_id] [int] NOT NULL;
|
||||
|
||||
-- Remove user_id column
|
||||
DROP INDEX [IX_guacamole_system_permission_user_id] ON [guacamole_system_permission];
|
||||
ALTER TABLE [guacamole_system_permission] DROP [PK_guacamole_system_permission];
|
||||
ALTER TABLE [guacamole_system_permission] DROP [FK_guacamole_system_permission_user_id];
|
||||
ALTER TABLE [guacamole_system_permission] DROP COLUMN [user_id];
|
||||
|
||||
-- The entity_id column should now safely point to guacamole_entity entries
|
||||
ALTER TABLE [guacamole_system_permission]
|
||||
ADD CONSTRAINT [FK_guacamole_system_permission_entity_id]
|
||||
FOREIGN KEY ([entity_id])
|
||||
REFERENCES [guacamole_entity] ([entity_id])
|
||||
ON DELETE CASCADE;
|
||||
|
||||
CREATE NONCLUSTERED INDEX [IX_guacamole_system_permission_entity_id]
|
||||
ON [guacamole_system_permission] ([entity_id]);
|
||||
|
||||
-- Add new primary key which uses entity_id
|
||||
ALTER TABLE [guacamole_system_permission]
|
||||
ADD CONSTRAINT [PK_guacamole_system_permission]
|
||||
PRIMARY KEY CLUSTERED ([entity_id], [permission]);
|
||||
GO
|
||||
|
||||
--
|
||||
-- Handle cascading deletion/updates of records in response to deletion of
|
||||
-- guacamole_entity records, where such deletion is not already covered by
|
||||
-- ON DELETE CASCADE or ON DELETE SET NULL.
|
||||
--
|
||||
|
||||
CREATE TRIGGER [guacamole_delete_entity]
|
||||
ON [guacamole_entity]
|
||||
INSTEAD OF DELETE
|
||||
AS BEGIN
|
||||
|
||||
-- Do not take trigger into account when producing row counts for the DELETE
|
||||
SET NOCOUNT ON;
|
||||
|
||||
-- Delete all associated permissions not covered by ON DELETE CASCADE
|
||||
DELETE FROM [guacamole_user_permission]
|
||||
WHERE [entity_id] IN (SELECT [entity_id] FROM DELETED);
|
||||
|
||||
DELETE FROM [guacamole_user_group_permission]
|
||||
WHERE [entity_id] IN (SELECT [entity_id] FROM DELETED);
|
||||
|
||||
-- Delete all associated group memberships not covered by ON DELETE CASCADE
|
||||
DELETE FROM [guacamole_user_group_member]
|
||||
WHERE [member_entity_id] IN (SELECT [entity_id] FROM DELETED);
|
||||
|
||||
-- Perform original deletion
|
||||
DELETE FROM [guacamole_entity]
|
||||
WHERE [entity_id] IN (SELECT [entity_id] FROM DELETED);
|
||||
|
||||
END
|
||||
GO
|
||||
|
||||
--
|
||||
-- Update guacamole_delete_connection_group trigger to remove descendant
|
||||
-- connections first.
|
||||
--
|
||||
|
||||
DROP TRIGGER [guacamole_delete_connection_group];
|
||||
GO
|
||||
|
||||
CREATE TRIGGER [guacamole_delete_connection_group]
|
||||
ON [guacamole_connection_group]
|
||||
INSTEAD OF DELETE
|
||||
AS BEGIN
|
||||
|
||||
-- Do not take trigger into account when producing row counts for the DELETE
|
||||
SET NOCOUNT ON;
|
||||
|
||||
-- Delete all descendant connections
|
||||
WITH [connection_groups] ([connection_group_id]) AS (
|
||||
SELECT [connection_group_id] FROM DELETED
|
||||
UNION ALL
|
||||
SELECT [guacamole_connection_group].[connection_group_id]
|
||||
FROM [guacamole_connection_group]
|
||||
JOIN [connection_groups] ON [connection_groups].[connection_group_id] = [guacamole_connection_group].[parent_id]
|
||||
)
|
||||
DELETE FROM [guacamole_connection]
|
||||
WHERE [parent_id] IN (
|
||||
SELECT [connection_group_id]
|
||||
FROM [connection_groups]
|
||||
);
|
||||
|
||||
-- Delete all requested connection groups, including descendants
|
||||
WITH [connection_groups] ([connection_group_id]) AS (
|
||||
SELECT [connection_group_id] FROM DELETED
|
||||
UNION ALL
|
||||
SELECT [guacamole_connection_group].[connection_group_id]
|
||||
FROM [guacamole_connection_group]
|
||||
JOIN [connection_groups] ON [connection_groups].[connection_group_id] = [guacamole_connection_group].[parent_id]
|
||||
)
|
||||
DELETE FROM [guacamole_connection_group]
|
||||
WHERE [connection_group_id] IN (
|
||||
SELECT [connection_group_id]
|
||||
FROM [connection_groups]
|
||||
);
|
||||
|
||||
END
|
||||
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 user group attributes. Each attribute is simply a
|
||||
-- name/value pair associated with a user 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_user_group_attribute] (
|
||||
|
||||
[user_group_id] [int] NOT NULL,
|
||||
[attribute_name] [nvarchar](128) NOT NULL,
|
||||
[attribute_value] [nvarchar](4000) NOT NULL,
|
||||
|
||||
CONSTRAINT [PK_guacamole_user_group_attribute]
|
||||
PRIMARY KEY CLUSTERED ([user_group_id], [attribute_name]),
|
||||
|
||||
CONSTRAINT [FK_guacamole_user_attribute_user_group_id]
|
||||
FOREIGN KEY ([user_group_id])
|
||||
REFERENCES [guacamole_user_group] ([user_group_id])
|
||||
ON DELETE CASCADE
|
||||
|
||||
);
|
||||
|
||||
CREATE NONCLUSTERED INDEX [IX_guacamole_user_group_attribute_user_id]
|
||||
ON [guacamole_user_group_attribute] ([user_group_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
|
@@ -0,0 +1,43 @@
|
||||
--
|
||||
-- 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.
|
||||
--
|
||||
|
||||
--
|
||||
-- Add new system-level audit permission
|
||||
--
|
||||
|
||||
EXEC sp_unbindrule 'guacamole_system_permission';
|
||||
DROP RULE [guacamole_system_permission_list];
|
||||
GO
|
||||
|
||||
CREATE RULE [guacamole_system_permission_list] AS @list IN (
|
||||
'CREATE_CONNECTION',
|
||||
'CREATE_CONNECTION_GROUP',
|
||||
'CREATE_SHARING_PROFILE',
|
||||
'CREATE_USER',
|
||||
'CREATE_USER_GROUP',
|
||||
'AUDIT',
|
||||
'ADMINISTER'
|
||||
);
|
||||
GO
|
||||
|
||||
EXEC sp_bindrule
|
||||
'guacamole_system_permission_list',
|
||||
'guacamole_system_permission';
|
||||
GO
|
||||
|
Reference in New Issue
Block a user