GUACAMOLE-52: Foreign keys in history table should be ON DELETE SET NULL. For sake of context, always store username and connection name in history table.

This commit is contained in:
Michael Jumper
2016-04-27 13:12:31 -07:00
parent 673fe42631
commit f4a3c5b31e
7 changed files with 225 additions and 39 deletions

View File

@@ -246,13 +246,12 @@ public abstract class AbstractGuacamoleTunnelService implements GuacamoleTunnelS
// Get associated models
AuthenticatedUser user = record.getUser();
UserModel userModel = user.getUser().getModel();
ConnectionRecordModel recordModel = new ConnectionRecordModel();
// Copy user information and timestamps into new record
recordModel.setUserID(userModel.getObjectID());
recordModel.setUsername(userModel.getIdentifier());
recordModel.setUsername(user.getIdentifier());
recordModel.setConnectionIdentifier(connection.getIdentifier());
recordModel.setConnectionName(connection.getName());
recordModel.setStartDate(record.getStartDate());
recordModel.setEndDate(new Date());

View File

@@ -230,11 +230,13 @@ CREATE TABLE `guacamole_user_permission` (
CREATE TABLE `guacamole_connection_history` (
`history_id` int(11) NOT NULL AUTO_INCREMENT,
`user_id` int(11) NOT NULL,
`connection_id` int(11) NOT NULL,
`start_date` datetime NOT NULL,
`end_date` datetime DEFAULT NULL,
`history_id` int(11) NOT NULL AUTO_INCREMENT,
`user_id` int(11) DEFAULT NULL,
`username` varchar(128) NOT NULL,
`connection_id` int(11) DEFAULT NULL,
`connection_name` varchar(128) NOT NULL,
`start_date` datetime NOT NULL,
`end_date` datetime DEFAULT NULL,
PRIMARY KEY (`history_id`),
KEY `user_id` (`user_id`),

View File

@@ -0,0 +1,89 @@
--
-- 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.
--
--
-- User and connection IDs within history table can now be null
--
ALTER TABLE guacamole_connection_history
MODIFY COLUMN user_id INT(11) DEFAULT NULL;
ALTER TABLE guacamole_connection_history
MODIFY COLUMN connection_id INT(11) DEFAULT NULL;
--
-- Add new username and connection_name columns to history table
--
ALTER TABLE guacamole_connection_history
ADD COLUMN username VARCHAR(128);
ALTER TABLE guacamole_connection_history
ADD COLUMN connection_name VARCHAR(128);
--
-- Populate new name columns by joining corresponding tables
--
UPDATE guacamole_connection_history
JOIN guacamole_user
ON guacamole_user.user_id = guacamole_connection_history.user_id
SET guacamole_connection_history.username = guacamole_user.username;
UPDATE guacamole_connection_history
JOIN guacamole_connection
ON guacamole_connection.connection_id =
guacamole_connection_history.connection_id
SET guacamole_connection_history.connection_name =
guacamole_connection.connection_name;
--
-- Set NOT NULL now that the column is fully populated
--
ALTER TABLE guacamole_connection_history
MODIFY username VARCHAR(128) NOT NULL;
ALTER TABLE guacamole_connection_history
MODIFY connection_name VARCHAR(128) NOT NULL;
--
-- Remove old foreign key constraints with ON DELETE CASCADE
--
ALTER TABLE guacamole_connection_history
DROP FOREIGN KEY guacamole_connection_history_ibfk_1;
ALTER TABLE guacamole_connection_history
DROP FOREIGN KEY guacamole_connection_history_ibfk_2;
--
-- Recreate foreign key constraints with ON DELETE SET NULL
--
ALTER TABLE guacamole_connection_history
ADD CONSTRAINT guacamole_connection_history_ibfk_1
FOREIGN KEY (user_id)
REFERENCES guacamole_user (user_id) ON DELETE SET NULL;
ALTER TABLE guacamole_connection_history
ADD CONSTRAINT guacamole_connection_history_ibfk_2
FOREIGN KEY (connection_id)
REFERENCES guacamole_connection (connection_id) ON DELETE SET NULL;

View File

@@ -37,17 +37,15 @@
<select id="select" resultMap="ConnectionRecordResultMap">
SELECT
guacamole_connection.connection_id,
guacamole_connection.connection_name,
guacamole_user.user_id,
guacamole_user.username,
guacamole_connection_history.connection_id,
guacamole_connection_history.connection_name,
guacamole_connection_history.user_id,
guacamole_connection_history.username,
guacamole_connection_history.start_date,
guacamole_connection_history.end_date
FROM guacamole_connection_history
JOIN guacamole_connection ON guacamole_connection_history.connection_id = guacamole_connection.connection_id
JOIN guacamole_user ON guacamole_connection_history.user_id = guacamole_user.user_id
WHERE
guacamole_connection.connection_id = #{identifier,jdbcType=VARCHAR}
guacamole_connection_history.connection_id = #{identifier,jdbcType=VARCHAR}
ORDER BY
guacamole_connection_history.start_date DESC,
guacamole_connection_history.end_date DESC
@@ -59,13 +57,18 @@
INSERT INTO guacamole_connection_history (
connection_id,
connection_name,
user_id,
username,
start_date,
end_date
)
VALUES (
#{record.connectionIdentifier,jdbcType=VARCHAR},
#{record.userID,jdbcType=INTEGER},
#{record.connectionName,jdbcType=VARCHAR},
(SELECT user_id FROM guacamole_user
WHERE username = #{record.username,jdbcType=VARCHAR}),
#{record.username,jdbcType=VARCHAR},
#{record.startDate,jdbcType=TIMESTAMP},
#{record.endDate,jdbcType=TIMESTAMP}
)
@@ -77,9 +80,9 @@
SELECT
guacamole_connection_history.connection_id,
guacamole_connection.connection_name,
guacamole_connection_history.connection_name,
guacamole_connection_history.user_id,
guacamole_user.username,
guacamole_connection_history.username,
guacamole_connection_history.start_date,
guacamole_connection_history.end_date
FROM guacamole_connection_history
@@ -132,9 +135,9 @@
SELECT
guacamole_connection_history.connection_id,
guacamole_connection.connection_name,
guacamole_connection_history.connection_name,
guacamole_connection_history.user_id,
guacamole_user.username,
guacamole_connection_history.username,
guacamole_connection_history.start_date,
guacamole_connection_history.end_date
FROM guacamole_connection_history

View File

@@ -274,11 +274,13 @@ CREATE INDEX ON guacamole_user_permission(user_id);
CREATE TABLE guacamole_connection_history (
history_id serial NOT NULL,
user_id integer NOT NULL,
connection_id integer NOT NULL,
start_date timestamptz NOT NULL,
end_date timestamptz DEFAULT NULL,
history_id serial NOT NULL,
user_id integer DEFAULT NULL,
username varchar(128) NOT NULL,
connection_id integer DEFAULT NULL,
connection_name varchar(128) NOT NULL,
start_date timestamptz NOT NULL,
end_date timestamptz DEFAULT NULL,
PRIMARY KEY (history_id),

View File

@@ -0,0 +1,90 @@
--
-- 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.
--
--
-- User and connection IDs within history table can now be null
--
ALTER TABLE guacamole_connection_history
ALTER COLUMN user_id SET DEFAULT NULL,
ALTER COLUMN user_id DROP NOT NULL;
ALTER TABLE guacamole_connection_history
ALTER COLUMN connection_id SET DEFAULT NULL,
ALTER COLUMN connection_id DROP NOT NULL;
--
-- Add new username and connection_name columns to history table
--
ALTER TABLE guacamole_connection_history
ADD COLUMN username varchar(128);
ALTER TABLE guacamole_connection_history
ADD COLUMN connection_name varchar(128);
--
-- Populate new name columns by joining corresponding tables
--
UPDATE guacamole_connection_history
SET username = guacamole_user.username
FROM guacamole_user
WHERE guacamole_user.user_id = guacamole_connection_history.user_id;
UPDATE guacamole_connection_history
SET connection_name = guacamole_connection.connection_name
FROM guacamole_connection
WHERE guacamole_connection.connection_id =
guacamole_connection_history.connection_id;
--
-- Set NOT NULL now that the column is fully populated
--
ALTER TABLE guacamole_connection_history
ALTER COLUMN username SET NOT NULL;
ALTER TABLE guacamole_connection_history
ALTER COLUMN connection_name SET NOT NULL;
--
-- Remove old foreign key constraints with ON DELETE CASCADE
--
ALTER TABLE guacamole_connection_history
DROP CONSTRAINT guacamole_connection_history_ibfk_1;
ALTER TABLE guacamole_connection_history
DROP CONSTRAINT guacamole_connection_history_ibfk_2;
--
-- Recreate foreign key constraints with ON DELETE SET NULL
--
ALTER TABLE guacamole_connection_history
ADD CONSTRAINT guacamole_connection_history_ibfk_1
FOREIGN KEY (user_id)
REFERENCES guacamole_user (user_id) ON DELETE SET NULL;
ALTER TABLE guacamole_connection_history
ADD CONSTRAINT guacamole_connection_history_ibfk_2
FOREIGN KEY (connection_id)
REFERENCES guacamole_connection (connection_id) ON DELETE SET NULL;

View File

@@ -37,17 +37,15 @@
<select id="select" resultMap="ConnectionRecordResultMap">
SELECT
guacamole_connection.connection_id,
guacamole_connection.connection_name,
guacamole_user.user_id,
guacamole_user.username,
guacamole_connection_history.connection_id,
guacamole_connection_history.connection_name,
guacamole_connection_history.user_id,
guacamole_connection_history.username,
guacamole_connection_history.start_date,
guacamole_connection_history.end_date
FROM guacamole_connection_history
JOIN guacamole_connection ON guacamole_connection_history.connection_id = guacamole_connection.connection_id
JOIN guacamole_user ON guacamole_connection_history.user_id = guacamole_user.user_id
WHERE
guacamole_connection.connection_id = #{identifier,jdbcType=INTEGER}::integer
guacamole_connection_history.connection_id = #{identifier,jdbcType=INTEGER}::integer
ORDER BY
guacamole_connection_history.start_date DESC,
guacamole_connection_history.end_date DESC
@@ -59,13 +57,18 @@
INSERT INTO guacamole_connection_history (
connection_id,
connection_name,
user_id,
username,
start_date,
end_date
)
VALUES (
#{record.connectionIdentifier,jdbcType=INTEGER}::integer,
#{record.userID,jdbcType=INTEGER},
#{record.connectionName,jdbcType=VARCHAR},
(SELECT user_id FROM guacamole_user
WHERE username = #{record.username,jdbcType=VARCHAR}),
#{record.username,jdbcType=VARCHAR},
#{record.startDate,jdbcType=TIMESTAMP},
#{record.endDate,jdbcType=TIMESTAMP}
)
@@ -77,14 +80,12 @@
SELECT
guacamole_connection_history.connection_id,
guacamole_connection.connection_name,
guacamole_connection_history.connection_name,
guacamole_connection_history.user_id,
guacamole_user.username,
guacamole_connection_history.username,
guacamole_connection_history.start_date,
guacamole_connection_history.end_date
FROM guacamole_connection_history
LEFT JOIN guacamole_connection ON guacamole_connection_history.connection_id = guacamole_connection.connection_id
LEFT JOIN guacamole_user ON guacamole_connection_history.user_id = guacamole_user.user_id
<!-- Search terms -->
<foreach collection="terms" item="term"
@@ -132,9 +133,9 @@
SELECT
guacamole_connection_history.connection_id,
guacamole_connection.connection_name,
guacamole_connection_history.connection_name,
guacamole_connection_history.user_id,
guacamole_user.username,
guacamole_connection_history.username,
guacamole_connection_history.start_date,
guacamole_connection_history.end_date
FROM guacamole_connection_history