hs-customer SQL-Scripts in Liquibase
This commit is contained in:
parent
a478fe4cf1
commit
8ba952a41d
@ -0,0 +1,14 @@
|
|||||||
|
--liquibase formatted sql
|
||||||
|
|
||||||
|
-- ============================================================================
|
||||||
|
--changeset hs-customer-MAIN-TABLE:1 endDelimiter:--//
|
||||||
|
-- ----------------------------------------------------------------------------
|
||||||
|
|
||||||
|
create table if not exists customer
|
||||||
|
(
|
||||||
|
uuid uuid unique references RbacObject (uuid),
|
||||||
|
reference int not null unique check (reference between 10000 and 99999),
|
||||||
|
prefix character(3) unique,
|
||||||
|
adminUserName varchar(63)
|
||||||
|
);
|
||||||
|
--//
|
@ -1,23 +1,23 @@
|
|||||||
-- ========================================================
|
--liquibase formatted sql
|
||||||
-- Customer example with RBAC
|
|
||||||
-- --------------------------------------------------------
|
|
||||||
|
|
||||||
set session session authorization default;
|
-- ============================================================================
|
||||||
|
--changeset hs-customer-rbac-CREATE-OBJECT:1 endDelimiter:--//
|
||||||
create table if not exists customer
|
-- ----------------------------------------------------------------------------
|
||||||
(
|
|
||||||
uuid uuid unique references RbacObject (uuid),
|
|
||||||
reference int not null unique check (reference between 10000 and 99999),
|
|
||||||
prefix character(3) unique,
|
|
||||||
adminUserName varchar(63)
|
|
||||||
);
|
|
||||||
|
|
||||||
|
/*
|
||||||
|
Creates the related RbacObject through a BEFORE INSERT TRIGGER.
|
||||||
|
*/
|
||||||
drop trigger if exists createRbacObjectForCustomer_Trigger on customer;
|
drop trigger if exists createRbacObjectForCustomer_Trigger on customer;
|
||||||
create trigger createRbacObjectForCustomer_Trigger
|
create trigger createRbacObjectForCustomer_Trigger
|
||||||
before insert
|
before insert
|
||||||
on customer
|
on customer
|
||||||
for each row
|
for each row
|
||||||
execute procedure createRbacObject();
|
execute procedure createRbacObject();
|
||||||
|
--//
|
||||||
|
|
||||||
|
-- ============================================================================
|
||||||
|
--changeset hs-customer-rbac-ROLE-DESCRIPTORS:1 endDelimiter:--//
|
||||||
|
-- ----------------------------------------------------------------------------
|
||||||
|
|
||||||
create or replace function customerOwner(customer customer)
|
create or replace function customerOwner(customer customer)
|
||||||
returns RbacRoleDescriptor
|
returns RbacRoleDescriptor
|
||||||
@ -42,9 +42,18 @@ create or replace function customerTenant(customer customer)
|
|||||||
begin
|
begin
|
||||||
return roleDescriptor('customer', customer.uuid, 'tenant');
|
return roleDescriptor('customer', customer.uuid, 'tenant');
|
||||||
end; $$;
|
end; $$;
|
||||||
|
--//
|
||||||
|
|
||||||
|
|
||||||
create or replace function createRbacRulesForCustomer()
|
-- ============================================================================
|
||||||
|
--changeset hs-customer-rbac-ROLES-CREATION:1 endDelimiter:--//
|
||||||
|
-- ----------------------------------------------------------------------------
|
||||||
|
|
||||||
|
/*
|
||||||
|
Creates the roles and their assignments for a new customer for the AFTER INSERT TRIGGER.
|
||||||
|
*/
|
||||||
|
|
||||||
|
create or replace function createRbacRolesForCustomer()
|
||||||
returns trigger
|
returns trigger
|
||||||
language plpgsql
|
language plpgsql
|
||||||
strict as $$
|
strict as $$
|
||||||
@ -83,12 +92,25 @@ begin
|
|||||||
return NEW;
|
return NEW;
|
||||||
end; $$;
|
end; $$;
|
||||||
|
|
||||||
drop trigger if exists createRbacRulesForCustomer_Trigger on customer;
|
/*
|
||||||
create trigger createRbacRulesForCustomer_Trigger
|
An AFTER INSERT TRIGGER which creates the role structure for a new customer.
|
||||||
|
*/
|
||||||
|
|
||||||
|
drop trigger if exists createRbacRolesForCustomer_Trigger on customer;
|
||||||
|
create trigger createRbacRolesForCustomer_Trigger
|
||||||
after insert
|
after insert
|
||||||
on customer
|
on customer
|
||||||
for each row
|
for each row
|
||||||
execute procedure createRbacRulesForCustomer();
|
execute procedure createRbacRolesForCustomer();
|
||||||
|
--//
|
||||||
|
|
||||||
|
-- ============================================================================
|
||||||
|
--changeset hs-customer-rbac-ROLES-REMOVAL:1 endDelimiter:--//
|
||||||
|
-- ----------------------------------------------------------------------------
|
||||||
|
|
||||||
|
/*
|
||||||
|
Deletes the roles and their assignments of a deleted customer for the BEFORE DELETE TRIGGER.
|
||||||
|
*/
|
||||||
|
|
||||||
create or replace function deleteRbacRulesForCustomer()
|
create or replace function deleteRbacRulesForCustomer()
|
||||||
returns trigger
|
returns trigger
|
||||||
@ -98,27 +120,34 @@ declare
|
|||||||
objectTable varchar = 'customer';
|
objectTable varchar = 'customer';
|
||||||
begin
|
begin
|
||||||
if TG_OP = 'DELETE' then
|
if TG_OP = 'DELETE' then
|
||||||
|
call deleteRole(findRoleId(customerOwner(OLD)));
|
||||||
-- delete the owner role (for admininstrators)
|
call deleteRole(findRoleId(customerAdmin(OLD)));
|
||||||
call deleteRole(findRoleId(objectTable || '#' || NEW.prefix || '.owner'));
|
call deleteRole(findRoleId(customerTenant(OLD)));
|
||||||
|
|
||||||
-- delete the customer admin role
|
|
||||||
call deleteRole(findRoleId(objectTable || '#' || NEW.prefix || '.admin'));
|
|
||||||
else
|
else
|
||||||
raise exception 'invalid usage of TRIGGER BEFORE DELETE';
|
raise exception 'invalid usage of TRIGGER BEFORE DELETE';
|
||||||
end if;
|
end if;
|
||||||
end; $$;
|
end; $$;
|
||||||
|
|
||||||
|
/*
|
||||||
|
An BEFORE DELETE TRIGGER which deletes the role structure of a customer.
|
||||||
|
*/
|
||||||
|
|
||||||
drop trigger if exists deleteRbacRulesForCustomer_Trigger on customer;
|
drop trigger if exists deleteRbacRulesForCustomer_Trigger on customer;
|
||||||
create trigger deleteRbacRulesForCustomer_Trigger
|
create trigger deleteRbacRulesForCustomer_Trigger
|
||||||
before delete
|
before delete
|
||||||
on customer
|
on customer
|
||||||
for each row
|
for each row
|
||||||
execute procedure deleteRbacRulesForCustomer();
|
execute procedure deleteRbacRulesForCustomer();
|
||||||
|
--//
|
||||||
|
|
||||||
-- create a restricted view to access the textual customer ids a idName
|
-- ============================================================================
|
||||||
set session session authorization default;
|
--changeset hs-customer-rbac-IDENTITY-VIEW:1 endDelimiter:--//
|
||||||
-- ALTER TABLE customer ENABLE ROW LEVEL SECURITY;
|
-- ----------------------------------------------------------------------------
|
||||||
|
|
||||||
|
/*
|
||||||
|
Creates a view to the customer main table which maps the identifying name
|
||||||
|
(in this case, the prefix) to the objectUuid.
|
||||||
|
*/
|
||||||
drop view if exists customer_iv;
|
drop view if exists customer_iv;
|
||||||
create or replace view customer_iv as
|
create or replace view customer_iv as
|
||||||
select distinct target.uuid, target.prefix as idName
|
select distinct target.uuid, target.prefix as idName
|
||||||
@ -126,58 +155,30 @@ select distinct target.uuid, target.prefix as idName
|
|||||||
-- TODO: Is it ok that everybody has access to this information?
|
-- TODO: Is it ok that everybody has access to this information?
|
||||||
grant all privileges on customer_iv to restricted;
|
grant all privileges on customer_iv to restricted;
|
||||||
|
|
||||||
|
/*
|
||||||
|
Returns the objectUuid for a given identifying name (in this case the prefix).
|
||||||
|
*/
|
||||||
create or replace function customerUuidByIdName(idName varchar)
|
create or replace function customerUuidByIdName(idName varchar)
|
||||||
returns uuid
|
returns uuid
|
||||||
language sql
|
language sql
|
||||||
strict as $$
|
strict as $$
|
||||||
select uuid from customer_iv iv where iv.idName = customerUuidByIdName.idName;
|
select uuid from customer_iv iv where iv.idName = customerUuidByIdName.idName;
|
||||||
$$;
|
$$;
|
||||||
|
--//
|
||||||
|
|
||||||
-- create RBAC restricted view
|
|
||||||
|
-- ============================================================================
|
||||||
|
--changeset hs-customer-rbac-RESTRICTED-VIEW:1 endDelimiter:--//
|
||||||
|
-- ----------------------------------------------------------------------------
|
||||||
|
/*
|
||||||
|
Creates a view to the customer main table with row-level limitatation
|
||||||
|
based on the 'view' permission of the current user or assumed roles.
|
||||||
|
*/
|
||||||
set session session authorization default;
|
set session session authorization default;
|
||||||
-- ALTER TABLE customer ENABLE ROW LEVEL SECURITY;
|
|
||||||
drop view if exists customer_rv;
|
drop view if exists customer_rv;
|
||||||
create or replace view customer_rv as
|
create or replace view customer_rv as
|
||||||
select distinct target.*
|
select distinct target.*
|
||||||
from customer as target
|
from customer as target
|
||||||
where target.uuid in (select queryAccessibleObjectUuidsOfSubjectIds('view', 'customer', currentSubjectIds()));
|
where target.uuid in (select queryAccessibleObjectUuidsOfSubjectIds('view', 'customer', currentSubjectIds()));
|
||||||
grant all privileges on customer_rv to restricted;
|
grant all privileges on customer_rv to restricted;
|
||||||
|
--//
|
||||||
|
|
||||||
-- generate Customer test data
|
|
||||||
|
|
||||||
set session session authorization default;
|
|
||||||
do language plpgsql $$
|
|
||||||
declare
|
|
||||||
currentTask varchar;
|
|
||||||
custReference integer;
|
|
||||||
custRowId uuid;
|
|
||||||
custPrefix varchar;
|
|
||||||
custAdminName varchar;
|
|
||||||
begin
|
|
||||||
set hsadminng.currentUser to '';
|
|
||||||
|
|
||||||
for t in 0..9
|
|
||||||
loop
|
|
||||||
currentTask = 'creating RBAC test customer #' || t;
|
|
||||||
set local hsadminng.currentUser to 'mike@hostsharing.net';
|
|
||||||
set local hsadminng.assumedRoles = '';
|
|
||||||
set local hsadminng.currentTask to currentTask;
|
|
||||||
|
|
||||||
-- When a new customer is created,
|
|
||||||
custReference = 10000 + t;
|
|
||||||
custRowId = uuid_generate_v4();
|
|
||||||
custPrefix = intToVarChar(t, 3);
|
|
||||||
custAdminName = 'admin@' || custPrefix || '.example.com';
|
|
||||||
|
|
||||||
raise notice 'creating customer %:%', custReference, custPrefix;
|
|
||||||
insert
|
|
||||||
into customer (reference, prefix, adminUserName)
|
|
||||||
values (custReference, custPrefix, custAdminName);
|
|
||||||
|
|
||||||
commit;
|
|
||||||
|
|
||||||
end loop;
|
|
||||||
|
|
||||||
end;
|
|
||||||
$$;
|
|
@ -0,0 +1,57 @@
|
|||||||
|
-- ============================================================================
|
||||||
|
--changeset hs-customer-TEST-DATA-GENERATOR:1 endDelimiter:--//
|
||||||
|
-- ----------------------------------------------------------------------------
|
||||||
|
|
||||||
|
create or replace procedure createCustomerTestData(
|
||||||
|
startCount integer, -- count of auto generated rows before the run
|
||||||
|
endCount integer, -- count of auto generated rows after the run
|
||||||
|
doCommitAfterEach boolean -- only for mass data creation outside of Liquibase
|
||||||
|
)
|
||||||
|
language plpgsql as $$
|
||||||
|
declare
|
||||||
|
currentTask varchar;
|
||||||
|
custReference integer;
|
||||||
|
custRowId uuid;
|
||||||
|
custPrefix varchar;
|
||||||
|
custAdminName varchar;
|
||||||
|
begin
|
||||||
|
set hsadminng.currentUser to '';
|
||||||
|
|
||||||
|
for t in startCount..endCount
|
||||||
|
loop
|
||||||
|
currentTask = 'creating RBAC test customer #' || t;
|
||||||
|
set local hsadminng.currentUser to 'mike@hostsharing.net';
|
||||||
|
set local hsadminng.assumedRoles = '';
|
||||||
|
set local hsadminng.currentTask to currentTask;
|
||||||
|
|
||||||
|
-- When a new customer is created,
|
||||||
|
custReference = 10000 + t;
|
||||||
|
custRowId = uuid_generate_v4();
|
||||||
|
custPrefix = intToVarChar(t, 3);
|
||||||
|
custAdminName = 'admin@' || custPrefix || '.example.com';
|
||||||
|
|
||||||
|
raise notice 'creating customer %:%', custReference, custPrefix;
|
||||||
|
insert
|
||||||
|
into customer (reference, prefix, adminUserName)
|
||||||
|
values (custReference, custPrefix, custAdminName);
|
||||||
|
|
||||||
|
if doCommitAfterEach then
|
||||||
|
commit;
|
||||||
|
end if;
|
||||||
|
|
||||||
|
end loop;
|
||||||
|
|
||||||
|
end; $$;
|
||||||
|
--//
|
||||||
|
|
||||||
|
|
||||||
|
-- ============================================================================
|
||||||
|
--changeset hs-customer-TEST-DATA-GENERATION:1 –context=dev,tc endDelimiter:--//
|
||||||
|
-- ----------------------------------------------------------------------------
|
||||||
|
|
||||||
|
do language plpgsql $$
|
||||||
|
begin
|
||||||
|
call createCustomerTestData(0, 2, false);
|
||||||
|
end;
|
||||||
|
$$;
|
||||||
|
--//
|
@ -15,5 +15,11 @@ databaseChangeLog:
|
|||||||
file: db/changelog/2022-07-28-030-rbac-statistics.sql
|
file: db/changelog/2022-07-28-030-rbac-statistics.sql
|
||||||
- include:
|
- include:
|
||||||
file: db/changelog/2022-07-29-050-hs-base.sql
|
file: db/changelog/2022-07-29-050-hs-base.sql
|
||||||
|
- include:
|
||||||
|
file: db/changelog/2022-07-29-060-hs-customer.sql
|
||||||
|
- include:
|
||||||
|
file: db/changelog/2022-07-29-061-hs-customer-rbac.sql
|
||||||
|
- include:
|
||||||
|
file: db/changelog/2022-07-29-062-hs-customer-test-data.sql
|
||||||
|
|
||||||
|
|
||||||
|
Loading…
Reference in New Issue
Block a user