GUAC-1103: Translate copied MySQL schema to PostgreSQL.

This commit is contained in:
Michael Jumper
2015-03-02 15:15:38 -08:00
parent 15240cc7b1
commit 4e08c10f94
2 changed files with 161 additions and 116 deletions

View File

@@ -1,5 +1,5 @@
-- --
-- Copyright (C) 2013 Glyptodon LLC -- Copyright (C) 2015 Glyptodon LLC
-- --
-- Permission is hereby granted, free of charge, to any person obtaining a copy -- Permission is hereby granted, free of charge, to any person obtaining a copy
-- of this software and associated documentation files (the "Software"), to deal -- of this software and associated documentation files (the "Software"), to deal
@@ -20,26 +20,62 @@
-- THE SOFTWARE. -- THE SOFTWARE.
-- --
--
-- Connection group types
--
CREATE TYPE guacamole_connection_group_type AS ENUM(
'ORGANIZATIONAL',
'BALANCING'
);
--
-- Object permission types
--
CREATE TYPE guacamole_object_permission_type AS ENUM(
'READ',
'UPDATE',
'DELETE',
'ADMINISTER'
);
--
-- System permission types
--
CREATE TYPE guacamole_system_permission_type AS ENUM(
'CREATE_CONNECTION',
'CREATE_CONNECTION_GROUP',
'CREATE_USER',
'ADMINISTER'
);
-- --
-- Table of connection groups. Each connection group has a name. -- Table of connection groups. Each connection group has a name.
-- --
CREATE TABLE `guacamole_connection_group` ( CREATE TABLE guacamole_connection_group (
`connection_group_id` int(11) NOT NULL AUTO_INCREMENT, connection_group_id serial NOT NULL,
`parent_id` int(11), parent_id integer,
`connection_group_name` varchar(128) NOT NULL, connection_group_name varchar(128) NOT NULL,
`type` enum('ORGANIZATIONAL', type guacamole_connection_group_type
'BALANCING') NOT NULL DEFAULT 'ORGANIZATIONAL', NOT NULL DEFAULT 'ORGANIZATIONAL',
PRIMARY KEY (`connection_group_id`), PRIMARY KEY (connection_group_id),
UNIQUE KEY `connection_group_name_parent` (`connection_group_name`, `parent_id`),
CONSTRAINT `guacamole_connection_group_ibfk_1` CONSTRAINT connection_group_name_parent
FOREIGN KEY (`parent_id`) UNIQUE (connection_group_name, parent_id),
REFERENCES `guacamole_connection_group` (`connection_group_id`) ON DELETE CASCADE
) ENGINE=InnoDB DEFAULT CHARSET=utf8; CONSTRAINT guacamole_connection_group_ibfk_1
FOREIGN KEY (parent_id)
REFERENCES guacamole_connection_group (connection_group_id)
ON DELETE CASCADE
);
CREATE INDEX ON guacamole_connection_group(parent_id);
-- --
-- Table of connections. Each connection has a name, protocol, and -- Table of connections. Each connection has a name, protocol, and
@@ -47,156 +83,164 @@ CREATE TABLE `guacamole_connection_group` (
-- A connection may belong to a connection group. -- A connection may belong to a connection group.
-- --
CREATE TABLE `guacamole_connection` ( CREATE TABLE guacamole_connection (
`connection_id` int(11) NOT NULL AUTO_INCREMENT, connection_id serial NOT NULL,
`connection_name` varchar(128) NOT NULL, connection_name varchar(128) NOT NULL,
`parent_id` int(11), parent_id integer,
`protocol` varchar(32) NOT NULL, protocol varchar(32) NOT NULL,
PRIMARY KEY (`connection_id`), PRIMARY KEY (connection_id),
UNIQUE KEY `connection_name_parent` (`connection_name`, `parent_id`),
CONSTRAINT `guacamole_connection_ibfk_1` CONSTRAINT connection_name_parent
FOREIGN KEY (`parent_id`) UNIQUE (connection_name, parent_id),
REFERENCES `guacamole_connection_group` (`connection_group_id`) ON DELETE CASCADE
) ENGINE=InnoDB DEFAULT CHARSET=utf8; CONSTRAINT guacamole_connection_ibfk_1
FOREIGN KEY (parent_id)
REFERENCES guacamole_connection_group (connection_group_id)
ON DELETE CASCADE
);
CREATE INDEX ON guacamole_connection(parent_id);
-- --
-- Table of users. Each user has a unique username and a hashed password -- Table of users. Each user has a unique username and a hashed password
-- with corresponding salt. -- with corresponding salt.
-- --
CREATE TABLE `guacamole_user` ( CREATE TABLE guacamole_user (
`user_id` int(11) NOT NULL AUTO_INCREMENT, user_id serial NOT NULL,
`username` varchar(128) NOT NULL, username varchar(128) NOT NULL,
`password_hash` binary(32) NOT NULL, password_hash bytea NOT NULL,
`password_salt` binary(32) NOT NULL, password_salt bytea NOT NULL,
PRIMARY KEY (`user_id`), PRIMARY KEY (user_id),
UNIQUE KEY `username` (`username`)
) ENGINE=InnoDB DEFAULT CHARSET=utf8; CONSTRAINT username
UNIQUE (username)
);
-- --
-- Table of connection parameters. Each parameter is simply a name/value pair -- Table of connection parameters. Each parameter is simply a name/value pair
-- associated with a connection. -- associated with a connection.
-- --
CREATE TABLE `guacamole_connection_parameter` ( CREATE TABLE guacamole_connection_parameter (
`connection_id` int(11) NOT NULL, connection_id integer NOT NULL,
`parameter_name` varchar(128) NOT NULL, parameter_name varchar(128) NOT NULL,
`parameter_value` varchar(4096) NOT NULL, parameter_value varchar(4096) NOT NULL,
PRIMARY KEY (`connection_id`,`parameter_name`), PRIMARY KEY (connection_id,parameter_name),
CONSTRAINT `guacamole_connection_parameter_ibfk_1` CONSTRAINT guacamole_connection_parameter_ibfk_1
FOREIGN KEY (`connection_id`) FOREIGN KEY (connection_id)
REFERENCES `guacamole_connection` (`connection_id`) ON DELETE CASCADE REFERENCES guacamole_connection (connection_id) ON DELETE CASCADE
) ENGINE=InnoDB DEFAULT CHARSET=utf8; );
CREATE INDEX ON guacamole_connection_parameter(connection_id);
-- --
-- Table of connection permissions. Each connection permission grants a user -- Table of connection permissions. Each connection permission grants a user
-- specific access to a connection. -- specific access to a connection.
-- --
CREATE TABLE `guacamole_connection_permission` ( CREATE TABLE guacamole_connection_permission (
`user_id` int(11) NOT NULL, user_id integer NOT NULL,
`connection_id` int(11) NOT NULL, connection_id integer NOT NULL,
`permission` enum('READ', permission guacamole_object_permission_type NOT NULL,
'UPDATE',
'DELETE',
'ADMINISTER') NOT NULL,
PRIMARY KEY (`user_id`,`connection_id`,`permission`), PRIMARY KEY (user_id,connection_id,permission),
CONSTRAINT `guacamole_connection_permission_ibfk_1` CONSTRAINT guacamole_connection_permission_ibfk_1
FOREIGN KEY (`connection_id`) FOREIGN KEY (connection_id)
REFERENCES `guacamole_connection` (`connection_id`) ON DELETE CASCADE, REFERENCES guacamole_connection (connection_id) ON DELETE CASCADE,
CONSTRAINT `guacamole_connection_permission_ibfk_2` CONSTRAINT guacamole_connection_permission_ibfk_2
FOREIGN KEY (`user_id`) FOREIGN KEY (user_id)
REFERENCES `guacamole_user` (`user_id`) ON DELETE CASCADE REFERENCES guacamole_user (user_id) ON DELETE CASCADE
) ENGINE=InnoDB DEFAULT CHARSET=utf8; );
CREATE INDEX ON guacamole_connection_permission(connection_id);
CREATE INDEX ON guacamole_connection_permission(user_id);
-- --
-- Table of connection group permissions. Each group permission grants a user -- Table of connection group permissions. Each group permission grants a user
-- specific access to a connection group. -- specific access to a connection group.
-- --
CREATE TABLE `guacamole_connection_group_permission` ( CREATE TABLE guacamole_connection_group_permission (
`user_id` int(11) NOT NULL, user_id integer NOT NULL,
`connection_group_id` int(11) NOT NULL, connection_group_id integer NOT NULL,
`permission` enum('READ', permission guacamole_object_permission_type NOT NULL,
'UPDATE',
'DELETE',
'ADMINISTER') NOT NULL,
PRIMARY KEY (`user_id`,`connection_group_id`,`permission`), PRIMARY KEY (user_id,connection_group_id,permission),
CONSTRAINT `guacamole_connection_group_permission_ibfk_1` CONSTRAINT guacamole_connection_group_permission_ibfk_1
FOREIGN KEY (`connection_group_id`) FOREIGN KEY (connection_group_id)
REFERENCES `guacamole_connection_group` (`connection_group_id`) ON DELETE CASCADE, REFERENCES guacamole_connection_group (connection_group_id) ON DELETE CASCADE,
CONSTRAINT `guacamole_connection_group_permission_ibfk_2` CONSTRAINT guacamole_connection_group_permission_ibfk_2
FOREIGN KEY (`user_id`) FOREIGN KEY (user_id)
REFERENCES `guacamole_user` (`user_id`) ON DELETE CASCADE REFERENCES guacamole_user (user_id) ON DELETE CASCADE
) ENGINE=InnoDB DEFAULT CHARSET=utf8; );
CREATE INDEX ON guacamole_connection_group_permission(connection_group_id);
CREATE INDEX ON guacamole_connection_group_permission(user_id);
-- --
-- Table of system permissions. Each system permission grants a user a -- Table of system permissions. Each system permission grants a user a
-- system-level privilege of some kind. -- system-level privilege of some kind.
-- --
CREATE TABLE `guacamole_system_permission` ( CREATE TABLE guacamole_system_permission (
`user_id` int(11) NOT NULL, user_id integer NOT NULL,
`permission` enum('CREATE_CONNECTION', permission guacamole_system_permission_type NOT NULL,
'CREATE_CONNECTION_GROUP',
'CREATE_USER',
'ADMINISTER') NOT NULL,
PRIMARY KEY (`user_id`,`permission`), PRIMARY KEY (user_id,permission),
CONSTRAINT `guacamole_system_permission_ibfk_1` CONSTRAINT guacamole_system_permission_ibfk_1
FOREIGN KEY (`user_id`) FOREIGN KEY (user_id)
REFERENCES `guacamole_user` (`user_id`) ON DELETE CASCADE REFERENCES guacamole_user (user_id) ON DELETE CASCADE
) ENGINE=InnoDB DEFAULT CHARSET=utf8; );
CREATE INDEX ON guacamole_system_permission(user_id);
-- --
-- Table of user permissions. Each user permission grants a user access to -- Table of user permissions. Each user permission grants a user access to
-- another user (the "affected" user) for a specific type of operation. -- another user (the "affected" user) for a specific type of operation.
-- --
CREATE TABLE `guacamole_user_permission` ( CREATE TABLE guacamole_user_permission (
`user_id` int(11) NOT NULL, user_id integer NOT NULL,
`affected_user_id` int(11) NOT NULL, affected_user_id integer NOT NULL,
`permission` enum('READ', permission guacamole_object_permission_type NOT NULL,
'UPDATE',
'DELETE',
'ADMINISTER') NOT NULL,
PRIMARY KEY (`user_id`,`affected_user_id`,`permission`), PRIMARY KEY (user_id,affected_user_id,permission),
CONSTRAINT `guacamole_user_permission_ibfk_1` CONSTRAINT guacamole_user_permission_ibfk_1
FOREIGN KEY (`affected_user_id`) FOREIGN KEY (affected_user_id)
REFERENCES `guacamole_user` (`user_id`) ON DELETE CASCADE, REFERENCES guacamole_user (user_id) ON DELETE CASCADE,
CONSTRAINT `guacamole_user_permission_ibfk_2` CONSTRAINT guacamole_user_permission_ibfk_2
FOREIGN KEY (`user_id`) FOREIGN KEY (user_id)
REFERENCES `guacamole_user` (`user_id`) ON DELETE CASCADE REFERENCES guacamole_user (user_id) ON DELETE CASCADE
) ENGINE=InnoDB DEFAULT CHARSET=utf8; );
CREATE INDEX ON guacamole_user_permission(affected_user_id);
CREATE INDEX ON guacamole_user_permission(user_id);
-- --
-- Table of connection history records. Each record defines a specific user's -- Table of connection history records. Each record defines a specific user's
@@ -204,25 +248,26 @@ CREATE TABLE `guacamole_user_permission` (
-- (if any). -- (if any).
-- --
CREATE TABLE `guacamole_connection_history` ( CREATE TABLE guacamole_connection_history (
`history_id` int(11) NOT NULL AUTO_INCREMENT, history_id serial NOT NULL,
`user_id` int(11) NOT NULL, user_id integer NOT NULL,
`connection_id` int(11) NOT NULL, connection_id integer NOT NULL,
`start_date` datetime NOT NULL, start_date timestamptz NOT NULL,
`end_date` datetime DEFAULT NULL, end_date timestamptz DEFAULT NULL,
PRIMARY KEY (`history_id`), PRIMARY KEY (history_id),
KEY `user_id` (`user_id`),
KEY `connection_id` (`connection_id`),
CONSTRAINT `guacamole_connection_history_ibfk_1` CONSTRAINT guacamole_connection_history_ibfk_1
FOREIGN KEY (`user_id`) FOREIGN KEY (user_id)
REFERENCES `guacamole_user` (`user_id`) ON DELETE CASCADE, REFERENCES guacamole_user (user_id) ON DELETE CASCADE,
CONSTRAINT `guacamole_connection_history_ibfk_2` CONSTRAINT guacamole_connection_history_ibfk_2
FOREIGN KEY (`connection_id`) FOREIGN KEY (connection_id)
REFERENCES `guacamole_connection` (`connection_id`) ON DELETE CASCADE REFERENCES guacamole_connection (connection_id) ON DELETE CASCADE
) ENGINE=InnoDB DEFAULT CHARSET=utf8; );
CREATE INDEX ON guacamole_connection_history(user_id);
CREATE INDEX ON guacamole_connection_history(connection_id);

View File

@@ -1,5 +1,5 @@
-- --
-- Copyright (C) 2013 Glyptodon LLC -- Copyright (C) 2015 Glyptodon LLC
-- --
-- Permission is hereby granted, free of charge, to any person obtaining a copy -- Permission is hereby granted, free of charge, to any person obtaining a copy
-- of this software and associated documentation files (the "Software"), to deal -- of this software and associated documentation files (the "Software"), to deal
@@ -22,8 +22,8 @@
-- Create default user "guacadmin" with password "guacadmin" -- Create default user "guacadmin" with password "guacadmin"
insert into guacamole_user values(1, 'guacadmin', insert into guacamole_user values(1, 'guacadmin',
x'CA458A7D494E3BE824F5E1E175A1556C0F8EEF2C2D7DF3633BEC4A29C4411960', -- 'guacadmin' E'\\xCA458A7D494E3BE824F5E1E175A1556C0F8EEF2C2D7DF3633BEC4A29C4411960', -- 'guacadmin'
x'FE24ADC5E11E2B25288D1704ABE67A79E342ECC26064CE69C5B3177795A82264'); E'\\xFE24ADC5E11E2B25288D1704ABE67A79E342ECC26064CE69C5B3177795A82264');
-- Grant this user create permissions -- Grant this user create permissions
insert into guacamole_system_permission values(1, 'CREATE_CONNECTION'); insert into guacamole_system_permission values(1, 'CREATE_CONNECTION');