VirtualBox

source: vbox/trunk/src/VBox/ValidationKit/testmanager/core/useraccount.pgsql@ 65914

Last change on this file since 65914 was 65914, checked in by vboxsync, 8 years ago

testmanager: Added Users::fReadOnly and the necessary checks associated with it.

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

© 2024 Oracle Support Privacy / Do Not Sell My Info Terms of Use Trademark Policy Automated Access Etiquette