1 | -- $Id: useraccount.pgsql 106061 2024-09-16 14:03:52Z vboxsync $
|
---|
2 | --- @file
|
---|
3 | -- VBox Test Manager Database Stored Procedures - UserAccounts.
|
---|
4 | --
|
---|
5 |
|
---|
6 | --
|
---|
7 | -- Copyright (C) 2012-2024 Oracle and/or its affiliates.
|
---|
8 | --
|
---|
9 | -- This file is part of VirtualBox base platform packages, as
|
---|
10 | -- available from https://www.virtualbox.org.
|
---|
11 | --
|
---|
12 | -- This program is free software; you can redistribute it and/or
|
---|
13 | -- modify it under the terms of the GNU General Public License
|
---|
14 | -- as published by the Free Software Foundation, in version 3 of the
|
---|
15 | -- License.
|
---|
16 | --
|
---|
17 | -- This program is distributed in the hope that it will be useful, but
|
---|
18 | -- WITHOUT ANY WARRANTY; without even the implied warranty of
|
---|
19 | -- MERCHANTABILITY or FITNESS FOR A PARTICULAR PURPOSE. See the GNU
|
---|
20 | -- General Public License for more details.
|
---|
21 | --
|
---|
22 | -- You should have received a copy of the GNU General Public License
|
---|
23 | -- along with this program; if not, see <https://www.gnu.org/licenses>.
|
---|
24 | --
|
---|
25 | -- The contents of this file may alternatively be used under the terms
|
---|
26 | -- of the Common Development and Distribution License Version 1.0
|
---|
27 | -- (CDDL), a copy of it is provided in the "COPYING.CDDL" file included
|
---|
28 | -- in the VirtualBox distribution, in which case the provisions of the
|
---|
29 | -- CDDL are applicable instead of those of the GPL.
|
---|
30 | --
|
---|
31 | -- You may elect to license modified versions of this file under the
|
---|
32 | -- terms and conditions of either the GPL or the CDDL or both.
|
---|
33 | --
|
---|
34 | -- SPDX-License-Identifier: GPL-3.0-only OR CDDL-1.0
|
---|
35 | --
|
---|
36 |
|
---|
37 | \set ON_ERROR_STOP 1
|
---|
38 | \connect testmanager;
|
---|
39 |
|
---|
40 | ---
|
---|
41 | -- Checks if the user name and login name are unique, ignoring a_uidIgnore.
|
---|
42 | -- Raises exception if duplicates are found.
|
---|
43 | --
|
---|
44 | -- @internal
|
---|
45 | --
|
---|
46 | CREATE OR REPLACE FUNCTION UserAccountLogic_checkUniqueUser(a_sUsername TEXT, a_sLoginName TEXT, a_uidIgnore INTEGER)
|
---|
47 | RETURNS VOID AS $$
|
---|
48 | DECLARE
|
---|
49 | v_cRows INTEGER;
|
---|
50 | BEGIN
|
---|
51 | -- sUserName
|
---|
52 | SELECT COUNT(*) INTO v_cRows
|
---|
53 | FROM Users
|
---|
54 | WHERE sUsername = a_sUsername
|
---|
55 | AND tsExpire = 'infinity'::TIMESTAMP
|
---|
56 | AND uid <> a_uidIgnore;
|
---|
57 | IF v_cRows <> 0 THEN
|
---|
58 | RAISE EXCEPTION 'Duplicate user name "%" (% times)', a_sUsername, v_cRows;
|
---|
59 | END IF;
|
---|
60 |
|
---|
61 | -- sLoginName
|
---|
62 | SELECT COUNT(*) INTO v_cRows
|
---|
63 | FROM Users
|
---|
64 | WHERE sLoginName = a_sLoginName
|
---|
65 | AND tsExpire = 'infinity'::TIMESTAMP
|
---|
66 | AND uid <> a_uidIgnore;
|
---|
67 | IF v_cRows <> 0 THEN
|
---|
68 | RAISE EXCEPTION 'Duplicate login name "%" (% times)', a_sUsername, v_cRows;
|
---|
69 | END IF;
|
---|
70 | END;
|
---|
71 | $$ LANGUAGE plpgsql;
|
---|
72 |
|
---|
73 | ---
|
---|
74 | -- Check that the user account exists.
|
---|
75 | -- Raises exception if it doesn't.
|
---|
76 | --
|
---|
77 | -- @internal
|
---|
78 | --
|
---|
79 | CREATE OR REPLACE FUNCTION UserAccountLogic_checkExists(a_uid INTEGER) RETURNS VOID AS $$
|
---|
80 | DECLARE
|
---|
81 | v_cUpdatedRows INTEGER;
|
---|
82 | BEGIN
|
---|
83 | IF NOT EXISTS( SELECT *
|
---|
84 | FROM Users
|
---|
85 | WHERE uid = a_uid
|
---|
86 | AND tsExpire = 'infinity'::TIMESTAMP ) THEN
|
---|
87 | RAISE EXCEPTION 'User with ID % does not currently exist', a_uid;
|
---|
88 | END IF;
|
---|
89 | END;
|
---|
90 | $$ LANGUAGE plpgsql;
|
---|
91 |
|
---|
92 | ---
|
---|
93 | -- Historize a row.
|
---|
94 | -- @internal
|
---|
95 | --
|
---|
96 | CREATE OR REPLACE FUNCTION UserAccountLogic_historizeEntry(a_uid INTEGER, a_tsExpire TIMESTAMP WITH TIME ZONE)
|
---|
97 | RETURNS VOID AS $$
|
---|
98 | DECLARE
|
---|
99 | v_cUpdatedRows INTEGER;
|
---|
100 | BEGIN
|
---|
101 | UPDATE Users
|
---|
102 | SET tsExpire = a_tsExpire
|
---|
103 | WHERE uid = a_uid
|
---|
104 | AND tsExpire = 'infinity'::TIMESTAMP;
|
---|
105 | GET DIAGNOSTICS v_cUpdatedRows = ROW_COUNT;
|
---|
106 | IF v_cUpdatedRows <> 1 THEN
|
---|
107 | IF v_cUpdatedRows = 0 THEN
|
---|
108 | RAISE EXCEPTION 'User with ID % does not currently exist', a_uid;
|
---|
109 | END IF;
|
---|
110 | RAISE EXCEPTION 'Integrity error in UserAccounts: % current rows with uid=%d', v_cUpdatedRows, a_uid;
|
---|
111 | END IF;
|
---|
112 | END;
|
---|
113 | $$ LANGUAGE plpgsql;
|
---|
114 |
|
---|
115 |
|
---|
116 | ---
|
---|
117 | -- Adds a new user.
|
---|
118 | --
|
---|
119 | CREATE OR REPLACE FUNCTION UserAccountLogic_addEntry(a_uidAuthor INTEGER, a_sUsername TEXT, a_sEmail TEXT, a_sFullName TEXT,
|
---|
120 | a_sLoginName TEXT, a_fReadOnly BOOLEAN)
|
---|
121 | RETURNS VOID AS $$
|
---|
122 | DECLARE
|
---|
123 | v_cRows INTEGER;
|
---|
124 | BEGIN
|
---|
125 | PERFORM UserAccountLogic_checkUniqueUser(a_sUsername, a_sLoginName, -1);
|
---|
126 | INSERT INTO Users(uidAuthor, sUsername, sEmail, sFullName, sLoginName)
|
---|
127 | VALUES (a_uidAuthor, a_sUsername, a_sEmail, a_sFullName, a_sLoginName);
|
---|
128 | END;
|
---|
129 | $$ LANGUAGE plpgsql;
|
---|
130 |
|
---|
131 | CREATE OR REPLACE FUNCTION UserAccountLogic_editEntry(a_uidAuthor INTEGER, a_uid INTEGER, a_sUsername TEXT, a_sEmail TEXT,
|
---|
132 | a_sFullName TEXT, a_sLoginName TEXT, a_fReadOnly BOOLEAN)
|
---|
133 | RETURNS VOID AS $$
|
---|
134 | BEGIN
|
---|
135 | PERFORM UserAccountLogic_checkExists(a_uid);
|
---|
136 | PERFORM UserAccountLogic_checkUniqueUser(a_sUsername, a_sLoginName, a_uid);
|
---|
137 |
|
---|
138 | PERFORM UserAccountLogic_historizeEntry(a_uid, CURRENT_TIMESTAMP);
|
---|
139 | INSERT INTO Users (uid, uidAuthor, sUsername, sEmail, sFullName, sLoginName, fReadOnly)
|
---|
140 | VALUES (a_uid, a_uidAuthor, a_sUsername, a_sEmail, a_sFullName, a_sLoginName, a_fReadOnly);
|
---|
141 | END;
|
---|
142 | $$ LANGUAGE plpgsql;
|
---|
143 |
|
---|
144 |
|
---|
145 | CREATE OR REPLACE FUNCTION UserAccountLogic_delEntry(a_uidAuthor INTEGER, a_uid INTEGER) RETURNS VOID AS $$
|
---|
146 | DECLARE
|
---|
147 | v_Row Users%ROWTYPE;
|
---|
148 | v_tsEffective TIMESTAMP WITH TIME ZONE;
|
---|
149 | BEGIN
|
---|
150 | --
|
---|
151 | -- To preserve the information about who deleted the record, we try to
|
---|
152 | -- add a dummy record which expires immediately. I say try because of
|
---|
153 | -- the primary key, we must let the new record be valid for 1 us. :-(
|
---|
154 | --
|
---|
155 |
|
---|
156 | SELECT * INTO STRICT v_Row
|
---|
157 | FROM Users
|
---|
158 | WHERE uid = a_uid
|
---|
159 | AND tsExpire = 'infinity'::TIMESTAMP;
|
---|
160 |
|
---|
161 | v_tsEffective := CURRENT_TIMESTAMP - INTERVAL '1 microsecond';
|
---|
162 | IF v_Row.tsEffective < v_tsEffective THEN
|
---|
163 | PERFORM UserAccountLogic_historizeEntry(a_uid, v_tsEffective);
|
---|
164 | v_Row.tsEffective = v_tsEffective;
|
---|
165 | v_Row.tsExpire = CURRENT_TIMESTAMP;
|
---|
166 | INSERT INTO Users VALUES (v_Row.*);
|
---|
167 | ELSE
|
---|
168 | PERFORM UserAccountLogic_historizeEntry(a_uid, CURRENT_TIMESTAMP);
|
---|
169 | END IF;
|
---|
170 |
|
---|
171 | EXCEPTION
|
---|
172 | WHEN NO_DATA_FOUND THEN
|
---|
173 | RAISE EXCEPTION 'User with ID % does not currently exist', a_uid;
|
---|
174 | WHEN TOO_MANY_ROWS THEN
|
---|
175 | RAISE EXCEPTION 'Integrity error in UserAccounts: Too many current rows for %', a_uid;
|
---|
176 | END;
|
---|
177 | $$ LANGUAGE plpgsql;
|
---|
178 |
|
---|