diff --git a/.run/00-util.sql.run.xml b/.run/00-util.sql.run.xml
new file mode 100644
index 00000000..765612b0
--- /dev/null
+++ b/.run/00-util.sql.run.xml
@@ -0,0 +1,8 @@
+
+
+
+ FILE
+
+
+
+
\ No newline at end of file
diff --git a/.run/10-rbac-base.sql.run.xml b/.run/10-rbac-base.sql.run.xml
new file mode 100644
index 00000000..161d087d
--- /dev/null
+++ b/.run/10-rbac-base.sql.run.xml
@@ -0,0 +1,8 @@
+
+
+
+ FILE
+
+
+
+
\ No newline at end of file
diff --git a/.run/12-rbac-role-builder.sql.run.xml b/.run/12-rbac-role-builder.sql.run.xml
new file mode 100644
index 00000000..795a8278
--- /dev/null
+++ b/.run/12-rbac-role-builder.sql.run.xml
@@ -0,0 +1,8 @@
+
+
+
+ FILE
+
+
+
+
\ No newline at end of file
diff --git a/.run/18--rbac-all.sql.run.xml b/.run/18--rbac-all.sql.run.xml
new file mode 100644
index 00000000..fb6890e6
--- /dev/null
+++ b/.run/18--rbac-all.sql.run.xml
@@ -0,0 +1,8 @@
+
+
+
+ FILE
+
+
+
+
\ No newline at end of file
diff --git a/.run/20-hs-base.sql.run.xml b/.run/20-hs-base.sql.run.xml
new file mode 100644
index 00000000..90368bd3
--- /dev/null
+++ b/.run/20-hs-base.sql.run.xml
@@ -0,0 +1,8 @@
+
+
+
+ FILE
+
+
+
+
\ No newline at end of file
diff --git a/.run/21-hs-customer.sql.run.xml b/.run/21-hs-customer.sql.run.xml
new file mode 100644
index 00000000..0b9f91e8
--- /dev/null
+++ b/.run/21-hs-customer.sql.run.xml
@@ -0,0 +1,8 @@
+
+
+
+ FILE
+
+
+
+
\ No newline at end of file
diff --git a/.run/22-hs-packages.sql.run.xml b/.run/22-hs-packages.sql.run.xml
new file mode 100644
index 00000000..84095cc5
--- /dev/null
+++ b/.run/22-hs-packages.sql.run.xml
@@ -0,0 +1,8 @@
+
+
+
+ FILE
+
+
+
+
\ No newline at end of file
diff --git a/.run/23-hs-unixuser.sql.run.xml b/.run/23-hs-unixuser.sql.run.xml
new file mode 100644
index 00000000..7b87185b
--- /dev/null
+++ b/.run/23-hs-unixuser.sql.run.xml
@@ -0,0 +1,8 @@
+
+
+
+ FILE
+
+
+
+
\ No newline at end of file
diff --git a/.run/24-hs-domain.sql.run.xml b/.run/24-hs-domain.sql.run.xml
new file mode 100644
index 00000000..678151b0
--- /dev/null
+++ b/.run/24-hs-domain.sql.run.xml
@@ -0,0 +1,8 @@
+
+
+
+ FILE
+
+
+
+
\ No newline at end of file
diff --git a/.run/25-hs-emailaddress.sql.run.xml b/.run/25-hs-emailaddress.sql.run.xml
new file mode 100644
index 00000000..e33ea706
--- /dev/null
+++ b/.run/25-hs-emailaddress.sql.run.xml
@@ -0,0 +1,8 @@
+
+
+
+ FILE
+
+
+
+
\ No newline at end of file
diff --git a/.run/29-hs-statistics.sql.run.xml b/.run/29-hs-statistics.sql.run.xml
new file mode 100644
index 00000000..e9790ad4
--- /dev/null
+++ b/.run/29-hs-statistics.sql.run.xml
@@ -0,0 +1,8 @@
+
+
+
+ FILE
+
+
+
+
\ No newline at end of file
diff --git a/.run/30-run-all.sql.run.xml b/.run/30-run-all.sql.run.xml
new file mode 100644
index 00000000..e17e8564
--- /dev/null
+++ b/.run/30-run-all.sql.run.xml
@@ -0,0 +1,8 @@
+
+
+
+ FILE
+
+
+
+
\ No newline at end of file
diff --git a/.run/run all up to emailaddresses.run.xml b/.run/run all up to emailaddresses.run.xml
new file mode 100644
index 00000000..ddbed0d5
--- /dev/null
+++ b/.run/run all up to emailaddresses.run.xml
@@ -0,0 +1,18 @@
+
+
+
+
+
+
+
+
+
+
+
+
+
+ FILE
+
+
+
+
\ No newline at end of file
diff --git a/sql/00-util.sql b/sql/00-util.sql
index 79326344..06755f11 100644
--- a/sql/00-util.sql
+++ b/sql/00-util.sql
@@ -35,4 +35,15 @@ ELSE
RETURN partial;
END IF;
END; $$;
-SELECT * FROM intToVarChar(211, 4);
+
+select * from intToVarChar(211, 4);
+
+CREATE OR REPLACE FUNCTION randomInRange(min INTEGER, max INTEGER)
+ RETURNS INT
+ RETURNS NULL ON NULL INPUT
+ language 'plpgsql' AS $$
+BEGIN
+ RETURN floor(random() * (max-min + 1) + min);
+END; $$;
+
+select * from randomInRange(0, 4);
diff --git a/sql/10-rbac-base.sql b/sql/10-rbac-base.sql
index f67ec657..2219c00c 100644
--- a/sql/10-rbac-base.sql
+++ b/sql/10-rbac-base.sql
@@ -45,7 +45,7 @@ CREATE TABLE RbacGrants
CREATE INDEX ON RbacGrants (ascendantUuid);
CREATE INDEX ON RbacGrants (descendantUuid);
-DROP DOMAIN IF EXISTS RbacOp CASCADE;
+-- DROP DOMAIN IF EXISTS RbacOp CASCADE;
CREATE DOMAIN RbacOp AS VARCHAR(67)
CHECK(
VALUE = '*'
@@ -56,7 +56,7 @@ CREATE DOMAIN RbacOp AS VARCHAR(67)
OR VALUE ~ '^add-[a-z]+$'
);
-DROP TABLE IF EXISTS RbacObject;
+-- DROP TABLE IF EXISTS RbacObject;
CREATE TABLE RbacObject
(
uuid uuid UNIQUE DEFAULT uuid_generate_v4(),
@@ -80,7 +80,7 @@ BEGIN
END; $$;
-DROP TABLE IF EXISTS RbacPermission;
+-- DROP TABLE IF EXISTS RbacPermission;
CREATE TABLE RbacPermission
( uuid uuid primary key references RbacReference (uuid) ON DELETE CASCADE,
objectUuid uuid not null,
@@ -111,13 +111,15 @@ BEGIN
END;
$$;
-CREATE OR REPLACE FUNCTION findRbacUser(userName varchar) -- TODO: rename to ...Id
+CREATE OR REPLACE FUNCTION findRbacUserId(userName varchar)
RETURNS uuid
RETURNS NULL ON NULL INPUT
LANGUAGE sql AS $$
SELECT uuid FROM RbacUser WHERE name = userName
$$;
+CREATE TYPE RbacWhenNotExists AS ENUM ('fail', 'create');
+
CREATE OR REPLACE FUNCTION getRbacUserId(userName varchar, whenNotExists RbacWhenNotExists)
RETURNS uuid
RETURNS NULL ON NULL INPUT
@@ -125,7 +127,7 @@ CREATE OR REPLACE FUNCTION getRbacUserId(userName varchar, whenNotExists RbacWhe
DECLARE
userUuid uuid;
BEGIN
- userUuid = findRbacUser(userName);
+ userUuid = findRbacUserId(userName);
IF ( userUuid IS NULL ) THEN
IF ( whenNotExists = 'fail') THEN
RAISE EXCEPTION 'RbacUser with name="%" not found', userName;
@@ -169,8 +171,6 @@ CREATE OR REPLACE FUNCTION findRoleId(roleName varchar)
SELECT uuid FROM RbacRole WHERE name = roleName
$$;
-CREATE TYPE RbacWhenNotExists AS ENUM ('fail', 'create');
-
CREATE OR REPLACE FUNCTION getRoleId(roleName varchar, whenNotExists RbacWhenNotExists)
RETURNS uuid
RETURNS NULL ON NULL INPUT
@@ -265,7 +265,7 @@ BEGIN
END IF;
-- INSERT INTO RbacGrants (ascendantUuid, descendantUuid, apply) VALUES (superRoleId, subRoleId, doapply); -- assumeV1
- INSERT INTO RbacGrants (ascendantUuid, descendantUuid, follow)VALUES (superRoleId, subRoleId, doFollow)
+ INSERT INTO RbacGrants (ascendantUuid, descendantUuid, follow) VALUES (superRoleId, subRoleId, doFollow)
ON CONFLICT DO NOTHING ; -- TODO: remove?
END; $$;
@@ -288,7 +288,7 @@ BEGIN
-- INSERT INTO RbacGrants (ascendantUuid, descendantUuid, apply) VALUES (userId, roleId, true); -- assumeV1
INSERT INTO RbacGrants (ascendantUuid, descendantUuid) VALUES (userId, roleId)
- ON CONFLICT DO NOTHING ; -- TODO: remove
+ ON CONFLICT DO NOTHING ; -- TODO: remove?
END; $$;
abort;
@@ -306,9 +306,12 @@ CREATE OR REPLACE FUNCTION nextLevel(level integer, maxDepth integer)
$$;
+abort;
+set local session authorization default;
+
CREATE OR REPLACE FUNCTION queryAccessibleObjectUuidsOfSubjectIds(
requiredOp RbacOp,
- forObjectTable varchar, -- TODO: test perforamance in joins!
+ forObjectTable varchar, -- TODO: test performance in joins!
subjectIds uuid[],
maxObjects integer = 16000)
RETURNS SETOF uuid
@@ -327,7 +330,7 @@ CREATE OR REPLACE FUNCTION queryAccessibleObjectUuidsOfSubjectIds(
SELECT "grant".descendantUuid, "grant".ascendantUuid, level+1 AS level
FROM RbacGrants "grant"
INNER JOIN grants recur ON recur.descendantUuid = "grant".ascendantUuid
- WHERE follow
+ WHERE follow
) SELECT descendantUuid
FROM grants
) as granted
@@ -345,12 +348,18 @@ CREATE OR REPLACE FUNCTION queryAccessibleObjectUuidsOfSubjectIds(
END;
$$;
+SET SESSION AUTHORIZATION DEFAULT;
+CREATE ROLE admin;
+GRANT ALL PRIVILEGES ON ALL TABLES IN SCHEMA public TO admin;
+CREATE ROLE restricted;
+GRANT ALL PRIVILEGES ON ALL TABLES IN SCHEMA public TO restricted;
+
abort;
set local session authorization restricted;
begin transaction;
-set local statement_timeout TO '5s';
+set local statement_timeout TO '15s';
select count(*)
- from queryAccessibleObjectUuidsOfSubjectIds('view', 'customer', ARRAY[findRbacUser('mike@hostsharing.net')], 10000);
+ from queryAccessibleObjectUuidsOfSubjectIds('view', 'customer', ARRAY[findRbacUserId('mike@hostsharing.net')], 10000);
end transaction;
---
@@ -389,7 +398,7 @@ set local session authorization restricted;
begin transaction;
-- set local statement_timeout TO '5s';
set local statement_timeout TO '5min';
-select count(*) from queryRequiredPermissionsOfSubjectIds('view', ARRAY[findRbacUser('mike@hostsharing.net')]);
+select count(*) from queryRequiredPermissionsOfSubjectIds('view', ARRAY[findRbacUserId('mike@hostsharing.net')]);
end transaction;
---
@@ -424,7 +433,7 @@ abort;
set local session authorization restricted;
begin transaction;
set local statement_timeout TO '5s';
- select count(*) from queryAllPermissionsOfSubjectIds(ARRAY[findRbacUser('mike@hostsharing.net')]);
+ select count(*) from queryAllPermissionsOfSubjectIds(ARRAY[findRbacUserId('mike@hostsharing.net')]);
end transaction;
---
@@ -564,18 +573,10 @@ CREATE OR REPLACE FUNCTION isPermissionGrantedToSubject(permissionId uuid, subje
);
$$;
-SET SESSION AUTHORIZATION DEFAULT;
-CREATE ROLE admin;
-GRANT ALL PRIVILEGES ON ALL TABLES IN SCHEMA public TO admin;
-CREATE ROLE restricted;
-GRANT ALL PRIVILEGES ON ALL TABLES IN SCHEMA public TO restricted;
-
-
-- ========================================================
--- Current User
+-- current user + assumed roles
-- --------------------------------------------------------
-
CREATE OR REPLACE FUNCTION currentUser()
RETURNS varchar(63)
STABLE LEAKPROOF
diff --git a/sql/11-rbac-view.sql b/sql/11--rbac-view-options.sql
similarity index 100%
rename from sql/11-rbac-view.sql
rename to sql/11--rbac-view-options.sql
diff --git a/sql/12-rbac-role-builder.sql b/sql/12-rbac-role-builder.sql
new file mode 100644
index 00000000..fc24de10
--- /dev/null
+++ b/sql/12-rbac-role-builder.sql
@@ -0,0 +1,208 @@
+
+
+-- ========================================================
+-- Role-Hierarcy helper functions
+-- --------------------------------------------------------
+
+CREATE TYPE RbacRoleType AS ENUM ('owner', 'admin', 'tenant');
+
+-- PERMISSIONS --------------------------------------------
+
+-- drop type RbacPermissions;
+CREATE TYPE RbacPermissions AS
+(
+ permissionUuids uuid[]
+);
+
+CREATE OR REPLACE FUNCTION grantingPermissions(forObjectUuid uuid, permitOps RbacOp[])
+ RETURNS RbacPermissions
+ LANGUAGE plpgsql STRICT AS $$
+BEGIN
+ RETURN ROW(createPermissions(forObjectUuid, permitOps))::RbacPermissions;
+END; $$;
+
+-- SUPER ROLES --------------------------------------------
+
+-- drop type RbacSuperRoles;
+CREATE TYPE RbacSuperRoles AS
+(
+ roleUuids uuid[]
+);
+
+-- drop function beneathRoles(roleName varchar);
+CREATE OR REPLACE FUNCTION beneathRoles(roleNames varchar[])
+ RETURNS RbacSuperRoles
+ LANGUAGE plpgsql STRICT AS $$
+DECLARE
+ superRoleName varchar;
+ superRoleUuids uuid[] := ARRAY[]::uuid[];
+BEGIN
+ FOREACH superRoleName IN ARRAY roleNames LOOP
+ superRoleUuids := superRoleUuids || getRoleId(superRoleName, 'fail');
+ END LOOP;
+
+ RETURN ROW(superRoleUuids)::RbacSuperRoles;
+END; $$;
+
+-- drop function beneathRole(roleName varchar);
+CREATE OR REPLACE FUNCTION beneathRole(roleName varchar)
+ RETURNS RbacSuperRoles
+ LANGUAGE plpgsql STRICT AS $$
+BEGIN
+ RETURN beneathRoles(ARRAY[roleName]);
+END; $$;
+
+-- drop function beneathRole(roleUuid uuid);
+CREATE OR REPLACE FUNCTION beneathRole(roleUuid uuid)
+ RETURNS RbacSuperRoles
+ LANGUAGE plpgsql STRICT AS $$
+BEGIN
+ RETURN ROW(ARRAY[roleUuid]::uuid[])::RbacSuperRoles;
+END; $$;
+
+-- drop function asTopLevelRole(roleName varchar);
+CREATE OR REPLACE FUNCTION asTopLevelRole()
+ RETURNS RbacSuperRoles
+ LANGUAGE plpgsql STRICT AS $$
+BEGIN
+ RETURN ROW(ARRAY[]::uuid[])::RbacSuperRoles;
+END; $$;
+
+-- SUB ROLES ----------------------------------------------
+
+CREATE TYPE RbacSubRoles AS
+(
+ roleUuids uuid[]
+);
+
+-- drop FUNCTION beingItselfA(roleUuid uuid)
+CREATE OR REPLACE FUNCTION beingItselfA(roleUuid uuid)
+ RETURNS RbacSubRoles
+ LANGUAGE plpgsql STRICT AS $$
+BEGIN
+ RETURN ROW(ARRAY[roleUuid]::uuid[])::RbacSubRoles;
+END; $$;
+
+-- drop FUNCTION beingItselfA(roleName varchar)
+CREATE OR REPLACE FUNCTION beingItselfA(roleName varchar)
+ RETURNS RbacSubRoles
+ LANGUAGE plpgsql STRICT AS $$
+BEGIN
+ RETURN beingItselfA(getRoleId(roleName, 'fail'));
+END; $$;
+
+-- USERS --------------------------------------------------
+
+-- drop type RbacUsers;
+CREATE TYPE RbacUsers AS
+(
+ userUuids uuid[]
+);
+
+-- drop function withUsers(userNames varchar);
+CREATE OR REPLACE FUNCTION withUsers(userNames varchar[])
+ RETURNS RbacUsers
+ LANGUAGE plpgsql STRICT AS $$
+DECLARE
+ userName varchar;
+ userUuids uuid[] := ARRAY[]::uuid[];
+BEGIN
+ FOREACH userName IN ARRAY userNames LOOP
+ userUuids := userUuids || getRbacUserId(userName, 'fail');
+ END LOOP;
+
+ RETURN ROW(userUuids)::RbacUsers;
+END; $$;
+
+
+-- DROP FUNCTION withUser(userName varchar, whenNotExists RbacWhenNotExists);
+CREATE OR REPLACE FUNCTION withUser(userName varchar, whenNotExists RbacWhenNotExists = 'fail')
+ RETURNS RbacUsers
+ RETURNS NULL ON NULL INPUT
+ LANGUAGE plpgsql AS $$
+BEGIN
+ RETURN ROW(ARRAY[getRbacUserId(userName, whenNotExists )]);
+END; $$;
+
+-- ROLE NAME BUILDER --------------------------------------
+
+CREATE OR REPLACE FUNCTION roleName(objectTable varchar, objectName varchar, roleType RbacRoleType )
+ RETURNS varchar
+ RETURNS NULL ON NULL INPUT
+ STABLE LEAKPROOF
+ LANGUAGE plpgsql AS $$
+BEGIN
+ RETURN objectTable || '#' || objectName || '.' || roleType;
+END; $$;
+
+
+-- CREATE ROLE MAIN FUNCTION ------------------------------
+
+CREATE OR REPLACE FUNCTION createRole(
+ roleName varchar,
+ permissions RbacPermissions,
+ superRoles RbacSuperRoles,
+ subRoles RbacSubRoles = null,
+ users RbacUsers = null
+)
+ RETURNS uuid
+ CALLED ON NULL INPUT
+ LANGUAGE plpgsql AS $$
+DECLARE
+ roleUuid uuid;
+ superRoleUuid uuid;
+ subRoleUuid uuid;
+ userUuid uuid;
+BEGIN
+ RAISE NOTICE 'creating role: %', roleName;
+ roleUuid = createRole(roleName);
+
+ call grantPermissionsToRole(roleUuid, permissions.permissionUuids);
+
+ IF superRoles IS NOT NULL THEN
+ FOREACH superRoleUuid IN ARRAY superRoles.roleuUids LOOP
+ call grantRoleToRole(roleUuid, superRoleUuid);
+ END LOOP;
+ END IF;
+
+ IF subRoles IS NOT NULL THEN
+ FOREACH subRoleUuid IN ARRAY subRoles.roleuUids LOOP
+ call grantRoleToRole(subRoleUuid, roleUuid);
+ END LOOP;
+ END IF;
+
+ IF users IS NOT NULL THEN
+ FOREACH userUuid IN ARRAY users.useruUids LOOP
+ call grantRoleToUser(roleUuid, userUuid);
+ END LOOP;
+ END IF;
+
+ RETURN roleUuid;
+END; $$;
+
+CREATE OR REPLACE FUNCTION createRole(
+ roleName varchar,
+ permissions RbacPermissions,
+ users RbacUsers = null
+)
+ RETURNS uuid
+ CALLED ON NULL INPUT
+ LANGUAGE plpgsql AS $$
+BEGIN
+ RETURN createRole(roleName, permissions, null, null, users);
+END; $$;
+
+CREATE OR REPLACE FUNCTION createRole(
+ roleName varchar,
+ permissions RbacPermissions,
+ subRoles RbacSubRoles,
+ users RbacUsers = null
+)
+ RETURNS uuid
+ CALLED ON NULL INPUT
+ LANGUAGE plpgsql AS $$
+BEGIN
+ RETURN createRole(roleName, permissions, null, subRoles, users);
+END; $$;
+
+
diff --git a/sql/rbac-statistics.sql b/sql/18-rbac-statistics.sql
similarity index 95%
rename from sql/rbac-statistics.sql
rename to sql/18-rbac-statistics.sql
index 3430bcb4..7bb5dac7 100644
--- a/sql/rbac-statistics.sql
+++ b/sql/18-rbac-statistics.sql
@@ -1,5 +1,5 @@
-DROP VIEW "RbacStatisticsV";
+DROP VIEW IF EXISTS "RbacStatisticsV";
CREATE VIEW "RbacStatisticsV" AS
SELECT no, to_char("count", '9 999 999 999') as "count", "table"
FROM (
diff --git a/sql/19-rbac-tests.sql b/sql/19--rbac-tests.sql
similarity index 100%
rename from sql/19-rbac-tests.sql
rename to sql/19--rbac-tests.sql
diff --git a/sql/21-hs-customer.sql b/sql/21-hs-customer.sql
index 2a93ad0a..99a0a091 100644
--- a/sql/21-hs-customer.sql
+++ b/sql/21-hs-customer.sql
@@ -17,40 +17,62 @@ CREATE TRIGGER createRbacObjectForCustomer_Trigger
BEFORE INSERT ON customer
FOR EACH ROW EXECUTE PROCEDURE createRbacObject();
+CREATE OR REPLACE FUNCTION customerOwner(customerName varchar)
+ RETURNS varchar
+ LANGUAGE plpgsql STRICT AS $$
+begin
+ return roleName('customer', customerName, 'owner');
+end; $$;
+
+CREATE OR REPLACE FUNCTION customerAdmin(customerName varchar)
+ RETURNS varchar
+ LANGUAGE plpgsql STRICT AS $$
+begin
+ return roleName('customer', customerName, 'admin');
+end; $$;
+
+CREATE OR REPLACE FUNCTION customerTenant(customerName varchar)
+ RETURNS varchar
+ LANGUAGE plpgsql STRICT AS $$
+begin
+ return roleName('customer', customerName, 'tenant');
+end; $$;
+
+
CREATE OR REPLACE FUNCTION createRbacRulesForCustomer()
RETURNS trigger
LANGUAGE plpgsql STRICT AS $$
DECLARE
- adminUserNameUuid uuid;
- customerOwnerRoleId uuid;
- customerAdminRoleId uuid;
+ customerOwnerUuid uuid;
+ customerAdminUuid uuid;
BEGIN
IF TG_OP <> 'INSERT' THEN
RAISE EXCEPTION 'invalid usage of TRIGGER AFTER INSERT';
END IF;
- -- an owner role is created and assigned to the administrators group
- customerOwnerRoleId = createRole('customer#'||NEW.prefix||'.owner');
- call grantRoleToRole(customerOwnerRoleId, getRoleId('administrators', 'create'));
- -- ... and permissions for all ops are assigned
- call grantPermissionsToRole(customerOwnerRoleId,
- createPermissions(forObjectUuid => NEW.uuid, permitOps => ARRAY['*']));
+ -- the owner role with full access for Hostsharing administrators
+ customerOwnerUuid = createRole(
+ customerOwner(NEW.prefix),
+ grantingPermissions(forObjectUuid => NEW.uuid, permitOps => ARRAY['*']),
+ beneathRole('administrators')
+ );
- -- ... also a customer admin role is created and granted to the customer owner role
- customerAdminRoleId = createRole('customer#'||NEW.prefix||'.admin');
- call grantRoleToRole(customerAdminRoleId, customerOwnerRoleId, false);
- -- ... to which a permission with view and add- ops is assigned
- call grantPermissionsToRole(customerAdminRoleId,
- createPermissions(forObjectUuid => NEW.uuid, permitOps => ARRAY['view', 'add-package']));
- -- if a admin user is given for the customer,
- IF (NEW.adminUserName IS NOT NULL) THEN
- -- ... the customer admin role is also assigned to the admin user of the customer
- adminUserNameUuid = findRoleId(NEW.adminUserName);
- IF ( adminUserNameUuid IS NULL ) THEN
- adminUserNameUuid = createRbacUser(NEW.adminUserName);
- END IF;
- call grantRoleToUser(customerAdminRoleId, adminUserNameUuid);
- END IF;
+ -- the admin role for the customer's admins, who can view and add products
+ customerAdminUuid = createRole(
+ customerAdmin(NEW.prefix),
+ grantingPermissions(forObjectUuid => NEW.uuid, permitOps => ARRAY['view', 'add-package']),
+ -- NO auto follow for customer owner to avoid exploding permissions for administrators
+ withUser(NEW.adminUserName, 'create') -- implicitly ignored if null
+ );
+
+ -- allow the customer owner role (thus administrators) to assume the customer admin role
+ call grantRoleToRole(customerAdminUuid, customerOwnerUuid, FALSE);
+
+ -- the tenant role which later can be used by owners+admins of sub-objects
+ perform createRole(
+ customerTenant(NEW.prefix),
+ grantingPermissions(forObjectUuid => NEW.uuid, permitOps => ARRAY['view'])
+ );
RETURN NEW;
END; $$;
@@ -109,7 +131,7 @@ DO LANGUAGE plpgsql $$
BEGIN
SET hsadminng.currentUser TO '';
- FOR t IN 0..9999 LOOP
+ FOR t IN 0..69 LOOP
currentTask = 'creating RBAC test customer #' || t;
SET LOCAL hsadminng.currentUser TO 'mike@hostsharing.net';
SET LOCAL hsadminng.assumedRoles = '';
diff --git a/sql/22-hs-packages.sql b/sql/22-hs-packages.sql
index 4f0e76d4..676f9b1f 100644
--- a/sql/22-hs-packages.sql
+++ b/sql/22-hs-packages.sql
@@ -11,6 +11,28 @@ CREATE TABLE IF NOT EXISTS package (
customerUuid uuid REFERENCES customer(uuid)
);
+CREATE OR REPLACE FUNCTION packageOwner(packageName varchar)
+ RETURNS varchar
+ LANGUAGE plpgsql STRICT AS $$
+begin
+ return roleName('package', packageName, 'owner');
+end; $$;
+
+CREATE OR REPLACE FUNCTION packageAdmin(packageName varchar)
+ RETURNS varchar
+ LANGUAGE plpgsql STRICT AS $$
+begin
+ return roleName('package', packageName, 'admin');
+end; $$;
+
+CREATE OR REPLACE FUNCTION packageTenant(packageName varchar)
+ RETURNS varchar
+ LANGUAGE plpgsql STRICT AS $$
+begin
+ return roleName('package', packageName, 'tenant');
+end; $$;
+
+
DROP TRIGGER IF EXISTS createRbacObjectForPackage_Trigger ON package;
CREATE TRIGGER createRbacObjectForPackage_Trigger
BEFORE INSERT ON package
@@ -21,8 +43,8 @@ CREATE OR REPLACE FUNCTION createRbacRulesForPackage()
LANGUAGE plpgsql STRICT AS $$
DECLARE
parentCustomer customer;
- packageOwnerRoleId uuid;
- packageTenantRoleId uuid;
+ packageOwnerRoleUuid uuid;
+ packageAdminRoleUuid uuid;
BEGIN
IF TG_OP <> 'INSERT' THEN
RAISE EXCEPTION 'invalid usage of TRIGGER AFTER INSERT';
@@ -30,21 +52,27 @@ BEGIN
SELECT * FROM customer AS c WHERE c.uuid=NEW.customerUuid INTO parentCustomer;
- -- an owner role is created and assigned to the customer's admin group
- packageOwnerRoleId = createRole('package#'||NEW.name||'.owner');
- call grantRoleToRole(packageOwnerRoleId, getRoleId('customer#'||parentCustomer.prefix||'.admin', 'fail'));
+ -- an owner role is created and assigned to the customer's admin role
+ packageOwnerRoleUuid = createRole(
+ packageOwner(NEW.name),
+ grantingPermissions(forObjectUuid => NEW.uuid, permitOps => ARRAY['*']),
+ beneathRole(customerAdmin(parentCustomer.prefix))
+ );
- -- ... and permissions for all ops are assigned
- call grantPermissionsToRole(packageOwnerRoleId,
- createPermissions(forObjectUuid => NEW.uuid, permitOps => ARRAY['*']));
+ -- an owner role is created and assigned to the package owner role
+ packageAdminRoleUuid = createRole(
+ packageAdmin(NEW.name),
+ grantingPermissions(forObjectUuid => NEW.uuid, permitOps => ARRAY['edit', 'add-unixuser']),
+ beneathRole(packageOwnerRoleUuid)
+ );
- -- ... also a package tenant role is created and assigned to the package owner as well
- packageTenantRoleId = createRole('package#'||NEW.name||'.tenant');
- call grantRoleToRole(packageTenantRoleId, packageOwnerRoleId);
-
- -- ... to which a permission with view operation is assigned
- call grantPermissionsToRole(packageTenantRoleId,
- createPermissions(forObjectUuid => NEW.uuid, permitOps => ARRAY['view']));
+ -- and a package tenant role is created and assigned to the package admin as well
+ perform createRole(
+ packageTenant(NEW.name),
+ grantingPermissions(forObjectUuid => NEW.uuid, permitOps => ARRAY ['view']),
+ beneathRole(packageAdminRoleUuid),
+ beingItselfA(customerTenant(parentCustomer.prefix))
+ );
RETURN NEW;
END; $$;
@@ -96,7 +124,7 @@ DO LANGUAGE plpgsql $$
SET hsadminng.currentUser TO '';
FOR cust IN (SELECT * FROM customer) LOOP
- FOR t IN 0..9 LOOP
+ FOR t IN 0..randominrange(1, 2) LOOP
pacName = cust.prefix || TO_CHAR(t, 'fm00');
currentTask = 'creating RBAC test package #'|| pacName || ' for customer ' || cust.prefix || ' #' || cust.uuid;
RAISE NOTICE 'task: %', currentTask;
diff --git a/sql/23-hs-unixuser.sql b/sql/23-hs-unixuser.sql
index 91b92c98..dcc992a6 100644
--- a/sql/23-hs-unixuser.sql
+++ b/sql/23-hs-unixuser.sql
@@ -11,6 +11,49 @@ CREATE TABLE IF NOT EXISTS UnixUser (
packageUuid uuid REFERENCES package(uuid)
);
+CREATE OR REPLACE FUNCTION unixUserOwner(unixUserName varchar)
+ RETURNS varchar
+ LANGUAGE plpgsql STRICT AS $$
+begin
+ return roleName('unixuser', unixUserName, 'owner');
+end; $$;
+
+CREATE OR REPLACE FUNCTION unixUserAdmin(unixUserName varchar)
+ RETURNS varchar
+ LANGUAGE plpgsql STRICT AS $$
+begin
+ return roleName('unixuser', unixUserName, 'admin');
+end; $$;
+
+CREATE OR REPLACE FUNCTION unixUserTenant(unixUserName varchar)
+ RETURNS varchar
+ LANGUAGE plpgsql STRICT AS $$
+begin
+ return roleName('unixuser', unixUserName, 'tenant');
+end; $$;
+
+CREATE OR REPLACE FUNCTION createUnixUserTenantRoleIfNotExists(unixUser UnixUser)
+ RETURNS uuid
+ RETURNS NULL ON NULL INPUT
+ LANGUAGE plpgsql AS $$
+DECLARE
+ unixUserTenantRoleName varchar;
+ unixUserTenantRoleUuid uuid;
+BEGIN
+ unixUserTenantRoleName = unixUserTenant(unixUser.name);
+ unixUserTenantRoleUuid = findRoleId(unixUserTenantRoleName);
+ IF unixUserTenantRoleUuid IS NOT NULL THEN
+ RETURN unixUserTenantRoleUuid;
+ END IF;
+
+ RETURN createRole(
+ unixUserTenantRoleName,
+ grantingPermissions(forObjectUuid => unixUser.uuid, permitOps => ARRAY['edit', 'add-domain']),
+ beneathRole(unixUserAdmin(unixUser.name))
+ );
+END; $$;
+
+
DROP TRIGGER IF EXISTS createRbacObjectForUnixUser_Trigger ON UnixUser;
CREATE TRIGGER createRbacObjectForUnixUser_Trigger
BEFORE INSERT ON UnixUser
@@ -23,7 +66,6 @@ DECLARE
parentPackage package;
unixuserOwnerRoleId uuid;
unixuserAdminRoleId uuid;
- unixuserTenantRoleId uuid;
BEGIN
IF TG_OP <> 'INSERT' THEN
RAISE EXCEPTION 'invalid usage of TRIGGER AFTER INSERT';
@@ -31,26 +73,22 @@ BEGIN
SELECT * FROM package WHERE uuid=NEW.packageUuid into parentPackage;
- -- an owner role is created and assigned to the package owner group
- unixuserOwnerRoleId = createRole('unixuser#'||NEW.name||'.owner');
- call grantRoleToRole(unixuserOwnerRoleId, getRoleId('package#'||parentPackage.name||'.owner', 'fail'));
- -- ... and permissions for all ops are assigned
- call grantPermissionsToRole(unixuserOwnerRoleId,
- createPermissions(forObjectUuid => NEW.uuid, permitOps => ARRAY['*']));
+ -- an owner role is created and assigned to the package's admin group
+ unixuserOwnerRoleId = createRole(
+ unixUserOwner(NEW.name),
+ grantingPermissions(forObjectUuid => NEW.uuid, permitOps => ARRAY['*']),
+ beneathRole(packageAdmin(parentPackage.name))
+ );
- -- ... also a unixuser admin role is created and assigned to the unixuser owner as well
- unixuserAdminRoleId = createRole('unixuser#'||NEW.name||'.admin');
- call grantRoleToRole(unixuserAdminRoleId, unixuserOwnerRoleId);
- -- ... to which a permission with view operation is assigned
- call grantPermissionsToRole(unixuserAdminRoleId,
- createPermissions(forObjectUuid => NEW.uuid, permitOps => ARRAY['edit', 'add-domain']));
+ -- and a unixuser admin role is created and assigned to the unixuser owner as well
+ unixuserAdminRoleId = createRole(
+ unixUserAdmin(NEW.name),
+ grantingPermissions(forObjectUuid => NEW.uuid, permitOps => ARRAY['edit', 'add-domain']),
+ beneathRole(unixuserOwnerRoleId),
+ beingItselfA(packageTenant(parentPackage.name))
+ );
- -- ... also a unixuser tenant role is created and assigned to the unixuser admin
- unixuserTenantRoleId = createRole('unixuser#'||NEW.name||'.tenant');
- call grantRoleToRole(unixuserTenantRoleId, unixuserAdminRoleId);
- -- ... to which a permission with view operation is assigned
- call grantPermissionsToRole(unixuserTenantRoleId,
- createPermissions(forObjectUuid => NEW.uuid, permitOps => ARRAY['view']));
+ -- a tenent role is only created on demand
RETURN NEW;
END; $$;
diff --git a/sql/24-hs-domain.sql b/sql/24-hs-domain.sql
index dc4afdef..ce730f40 100644
--- a/sql/24-hs-domain.sql
+++ b/sql/24-hs-domain.sql
@@ -16,12 +16,35 @@ CREATE TRIGGER createRbacObjectForDomain_Trigger
BEFORE INSERT ON Domain
FOR EACH ROW EXECUTE PROCEDURE createRbacObject();
+CREATE OR REPLACE FUNCTION domainOwner(unixUserName varchar, domainName varchar)
+ RETURNS varchar
+ LANGUAGE plpgsql STRICT AS $$
+begin
+ return roleName('domain', unixUserName || '/' || domainName, 'owner');
+end; $$;
+
+CREATE OR REPLACE FUNCTION domainAdmin(unixUserName varchar, domainName varchar)
+ RETURNS varchar
+ LANGUAGE plpgsql STRICT AS $$
+begin
+ return roleName('domain', unixUserName || '/' || domainName, 'admin');
+end; $$;
+
+CREATE OR REPLACE FUNCTION domainTenant(unixUserName varchar, domainName varchar)
+ RETURNS varchar
+ LANGUAGE plpgsql STRICT AS $$
+begin
+ return roleName('domain', unixUserName || '/' || domainName, 'tenant');
+end; $$;
+
+
CREATE OR REPLACE FUNCTION createRbacRulesForDomain()
RETURNS trigger
LANGUAGE plpgsql STRICT AS $$
DECLARE
- parentUser unixuser;
- domainOwnerRoleId uuid;
+ parentUser unixuser;
+ domainOwnerRoleUuid uuid;
+ domainAdminRoleUuid uuid;
BEGIN
IF TG_OP <> 'INSERT' THEN
RAISE EXCEPTION 'invalid usage of TRIGGER AFTER INSERT';
@@ -29,13 +52,27 @@ BEGIN
SELECT * FROM unixuser WHERE uuid=NEW.unixUserUuid into parentUser;
- -- an owner role is created and assigned to the unix user admin
- RAISE NOTICE 'creating domain owner role: %', 'domain#'||NEW.name||'.owner';
- domainOwnerRoleId = getRoleId('domain#'||NEW.name||'.owner', 'create');
- call grantRoleToRole(domainOwnerRoleId, getRoleId('unixuser#'||parentUser.name||'.admin', 'fail'));
- -- ... and permissions for all ops are assigned
- call grantPermissionsToRole(domainOwnerRoleId,
- createPermissions(forObjectUuid => NEW.uuid, permitOps => ARRAY['*']));
+ -- a domain owner role is created and assigned to the unixuser's admin role
+ domainOwnerRoleUuid = createRole(
+ domainOwner(parentUser.name, NEW.name),
+ grantingPermissions(forObjectUuid => NEW.uuid, permitOps => ARRAY['*']),
+ beneathRole(unixUserAdmin(parentUser.name))
+ );
+
+ -- a domain admin role is created and assigned to the domain's owner role
+ domainAdminRoleUuid = createRole(
+ domainAdmin(parentUser.name, NEW.name),
+ grantingPermissions(forObjectUuid => NEW.uuid, permitOps => ARRAY['edit', 'add-emailaddress']),
+ beneathRole(domainOwnerRoleUuid)
+ );
+
+ -- and a domain tenant role is created and assigned to the domain's admiin role
+ perform createRole(
+ domainTenant(parentUser.name, NEW.name),
+ grantingPermissions(forObjectUuid => NEW.uuid, permitOps => ARRAY['*']),
+ beneathRole(domainAdminRoleUuid),
+ beingItselfA(createUnixUserTenantRoleIfNotExists(parentUser))
+ );
RETURN NEW;
END; $$;
@@ -74,7 +111,7 @@ DO LANGUAGE plpgsql $$
FOR uu IN (SELECT * FROM unixuser) LOOP
IF ( random() < 0.3 ) THEN
- FOR t IN 0..2 LOOP
+ FOR t IN 0..1 LOOP
currentTask = 'creating RBAC test Domain #' || t || ' for UnixUser ' || uu.name|| ' #' || uu.uuid;
RAISE NOTICE 'task: %', currentTask;
@@ -85,7 +122,7 @@ DO LANGUAGE plpgsql $$
SET LOCAL hsadminng.currentTask TO currentTask;
INSERT INTO Domain (name, unixUserUuid)
- VALUES ('dom-' || t || '.' || pac.name || '.example.org' , uu.uuid);
+ VALUES ('dom-' || t || '.' || uu.name || '.example.org' , uu.uuid);
COMMIT;
END LOOP;
diff --git a/sql/25-hs-emailaddress.sql b/sql/25-hs-emailaddress.sql
index 7a37d9c2..49c25d06 100644
--- a/sql/25-hs-emailaddress.sql
+++ b/sql/25-hs-emailaddress.sql
@@ -16,35 +16,51 @@ CREATE TRIGGER createRbacObjectForEMailAddress_Trigger
BEFORE INSERT ON EMailAddress
FOR EACH ROW EXECUTE PROCEDURE createRbacObject();
+CREATE OR REPLACE FUNCTION emailAddressOwner(emailAddress varchar)
+ RETURNS varchar
+ LANGUAGE plpgsql STRICT AS $$
+begin
+ return roleName('emailaddress', emailAddress, 'owner');
+end; $$;
+
+CREATE OR REPLACE FUNCTION emailAddressAdmin(emailAddress varchar)
+ RETURNS varchar
+ LANGUAGE plpgsql STRICT AS $$
+begin
+ return roleName('emailaddress', emailAddress, 'admin');
+end; $$;
+
CREATE OR REPLACE FUNCTION createRbacRulesForEMailAddress()
RETURNS trigger
LANGUAGE plpgsql STRICT AS $$
DECLARE
- eMailAddress varchar;
- parentDomain domain;
- eMailAddressOwnerRoleId uuid;
- eMailAddressTenantRoleId uuid;
+ parentDomain record;
+ eMailAddress varchar;
+ eMailAddressOwnerRoleUuid uuid;
BEGIN
IF TG_OP <> 'INSERT' THEN
RAISE EXCEPTION 'invalid usage of TRIGGER AFTER INSERT';
END IF;
- SELECT * FROM domain WHERE uuid=NEW.domainUuid into parentDomain;
+ SELECT d.name as name, u.name as unixUserName FROM domain d
+ LEFT JOIN unixuser u ON u.uuid = d.unixuseruuid
+ WHERE d.uuid=NEW.domainUuid into parentDomain;
eMailAddress = NEW.localPart || '@' || parentDomain.name;
- -- an owner role is created and assigned to the domain owner
- eMailAddressOwnerRoleId = getRoleId('emailaddress#'||eMailAddress||'.owner', 'create');
- call grantRoleToRole(eMailAddressOwnerRoleId, getRoleId('domain#'||parentDomain.name||'.owner', 'fail'));
- -- ... and permissions for all ops are assigned
- call grantPermissionsToRole(eMailAddressOwnerRoleId,
- createPermissions(forObjectUuid => NEW.uuid, permitOps => ARRAY['*']));
+ -- an owner role is created and assigned to the domains's admin group
+ eMailAddressOwnerRoleUuid = createRole(
+ emailAddressOwner(eMailAddress),
+ grantingPermissions(forObjectUuid => NEW.uuid, permitOps => ARRAY['*']),
+ beneathRole(domainAdmin( parentDomain.unixUserName, parentDomain.name))
+ );
- -- a tenant role is created and assigned to a user with the new email address
- eMailAddressTenantRoleId = getRoleId('emailaddress#'||eMailAddress||'.tenant', 'create');
- call grantRoleToUser(eMailAddressTenantRoleId, getRbacUserId(eMailAddress, 'create'));
- -- ... and permissions for all ops are assigned
- call grantPermissionsToRole(eMailAddressTenantRoleId,
- createPermissions(forObjectUuid => NEW.uuid, permitOps => ARRAY['*'])); -- TODO '*' -> 'edit', 'view'
+ -- and an admin role is created and assigned to the unixuser owner as well
+ perform createRole(
+ emailAddressAdmin(eMailAddress),
+ grantingPermissions(forObjectUuid => NEW.uuid, permitOps => ARRAY['edit']),
+ beneathRole(eMailAddressOwnerRoleUuid),
+ beingItselfA(domainTenant(parentDomain.unixUserName, parentDomain.name))
+ );
RETURN NEW;
END; $$;
@@ -59,22 +75,6 @@ CREATE TRIGGER createRbacRulesForEMailAddress_Trigger
-- create RBAC restricted view
-abort;
-set session authorization default ;
-START TRANSACTION;
- SET LOCAL hsadminng.currentUser = 'mike@hostsharing.net';
- SET LOCAL hsadminng.assumedRoles = 'customer#bbb.owner;customer#bbc.owner';
- -- SET LOCAL hsadminng.assumedRoles = 'package#bbb00.owner;package#bbb01.owner';
-
- select count(*) from queryAccessibleObjectUuidsOfSubjectIds( 'view', currentSubjectIds(), 7) as a
- join rbacobject as o on a=o.uuid;
-
- /* SELECT DISTINCT target.*
- FROM EMailAddress AS target
- JOIN queryAccessibleObjectUuidsOfSubjectIds( 'view', currentSubjectIds()) AS allowedObjId
- ON target.uuid = allowedObjId;*/
-END TRANSACTION;
-
SET SESSION SESSION AUTHORIZATION DEFAULT;
ALTER TABLE EMailAddress ENABLE ROW LEVEL SECURITY;
DROP VIEW IF EXISTS EMailAddress_rv;
@@ -99,7 +99,7 @@ DO LANGUAGE plpgsql $$
SET hsadminng.currentUser TO '';
FOR dom IN (SELECT * FROM domain) LOOP
- FOR t IN 0..5 LOOP
+ FOR t IN 0..4 LOOP
currentTask = 'creating RBAC test EMailAddress #' || t || ' for Domain ' || dom.name;
RAISE NOTICE 'task: %', currentTask;
@@ -111,7 +111,7 @@ DO LANGUAGE plpgsql $$
SET LOCAL hsadminng.currentTask TO currentTask;
INSERT INTO EMailAddress (localPart, domainUuid)
- VALUES ('local' || t, dom.uuid);
+ VALUES ('local' || t, dom.uuid);
COMMIT;
END LOOP;
diff --git a/sql/28-hs-tests.sql b/sql/28--hs-tests.sql
similarity index 72%
rename from sql/28-hs-tests.sql
rename to sql/28--hs-tests.sql
index 029ba24f..46c72c86 100644
--- a/sql/28-hs-tests.sql
+++ b/sql/28--hs-tests.sql
@@ -35,16 +35,18 @@ ROLLBACK;
BEGIN TRANSACTION;
SET SESSION SESSION AUTHORIZATION restricted;
SET LOCAL hsadminng.currentUser = 'mike@hostsharing.net';
-SET LOCAL hsadminng.assumedRoles = 'customer#bbb.admin;customer#bbc.admin';
+SET LOCAL hsadminng.assumedRoles = 'customer#aab.admin;customer#aac.admin';
SELECT * FROM package_rv p;
END TRANSACTION;
+---
+
-- hostsharing admin assuming two customer admin role and listing all accessible unixusers
ROLLBACK;
BEGIN TRANSACTION;
SET SESSION SESSION AUTHORIZATION restricted;
SET LOCAL hsadminng.currentUser = 'mike@hostsharing.net';
-SET LOCAL hsadminng.assumedRoles = 'customer#bbb.admin;customer#bbc.admin';
+SET LOCAL hsadminng.assumedRoles = 'customer#aab.admin;customer#aac.admin';
SELECT c.prefix, c.reference, uu.*
FROM unixuser_rv uu
@@ -52,10 +54,12 @@ FROM unixuser_rv uu
JOIN customer_rv c ON c.uuid = p.customeruuid;
END TRANSACTION;
+---
+
BEGIN TRANSACTION;
SET SESSION SESSION AUTHORIZATION restricted;
SET LOCAL hsadminng.currentUser = 'mike@hostsharing.net';
-SET LOCAL hsadminng.assumedRoles = 'customer#bbb.admin;customer#bbc.admin';
+SET LOCAL hsadminng.assumedRoles = 'customer#aab.admin;customer#aac.admin';
SELECT p.name, uu.name, dom.name
FROM domain_rv dom
@@ -64,24 +68,26 @@ FROM domain_rv dom
JOIN customer_rv c ON c.uuid = p.customeruuid;
END TRANSACTION;
+---
+
BEGIN TRANSACTION;
SET SESSION SESSION AUTHORIZATION restricted;
SET LOCAL hsadminng.currentUser = 'mike@hostsharing.net';
-SET LOCAL hsadminng.assumedRoles = 'customer#bbb.admin;customer#bbc.admin';
--- TODO: we need tenant roles on parent objects
--- SET LOCAL hsadminng.assumedRoles = 'package#bbb03.owner;package#bbb08.owner';
+SET LOCAL hsadminng.assumedRoles = 'customer#aab.admin;customer#aac.admin';
-SELECT p.name as "package", ema.localPart || '@' || dom.name as "email-address"
-FROM emailaddress_rv ema
- JOIN domain_rv dom ON dom.uuid = ema.domainuuid
- JOIN unixuser_rv uu ON uu.uuid = dom.unixuseruuid
- JOIN package_rv p ON p.uuid = uu.packageuuid
- JOIN customer_rv c ON c.uuid = p.customeruuid;
+SELECT c.prefix, p.name as "package", ema.localPart || '@' || dom.name as "email-address"
+ FROM emailaddress_rv ema
+ JOIN domain_rv dom ON dom.uuid = ema.domainuuid
+ JOIN unixuser_rv uu ON uu.uuid = dom.unixuseruuid
+ JOIN package_rv p ON p.uuid = uu.packageuuid
+ JOIN customer_rv c ON c.uuid = p.customeruuid;
END TRANSACTION;
+---
+
ROLLBACK;
BEGIN TRANSACTION;
SET SESSION SESSION AUTHORIZATION restricted;
SET LOCAL hsadminng.currentUser = 'mike@hostsharing.net';
-select * from customer_rv c where c.prefix='bbb';
+select * from customer_rv c where c.prefix='aab';
END TRANSACTION;
diff --git a/sql/29-hs-statistics.sql b/sql/29-hs-statistics.sql
index 7dbb3f83..d296a2d9 100644
--- a/sql/29-hs-statistics.sql
+++ b/sql/29-hs-statistics.sql
@@ -5,7 +5,7 @@
DROP VIEW IF EXISTS "BusinessTableStatisticsV";
CREATE VIEW "BusinessTableStatisticsV" AS
-SELECT no, to_char("count", '999 999 999') as "count", to_char("required", '999 999 999') as "required", to_char("count"::float/"required"::float, '990.9') as "factor", "table"
+SELECT no, to_char("count", '999 999 999') as "count", to_char("required", '999 999 999') as "required", to_char("count"::float/"required"::float, '990.999') as "factor", "table"
FROM (select 1 as no, count(*) as "count", 7000 as "required", 'customers' as "table"
from customer
UNION
@@ -22,3 +22,5 @@ FROM (select 1 as no, count(*) as "count", 7000 as "required", 'customers' as "
from emailaddress
) totals
ORDER BY totals.no;
+
+SELECT * FROM "BusinessTableStatisticsV";