DDL - Roles and Privileges
OmniSci supports data security using a set of database object access privileges granted to users or roles.
- Users and Privileges
- Privilege Commands
- Common Privilege Levels for Non-Superusers
- Example Roles and Privileges Session
- Commands to Report Roles and Privileges
Users and Privileges
When you create a database, the omnisci
superuser is created by default. The omnisci
superuser is granted all privileges on all database objects. Superusers can create new users that, by default, have no database object privileges.
Superusers can grant users selective access privileges on multiple database objects using two mechanisms: role-based privileges and user-based privileges.
Role-based Privileges
- Grant roles access privileges on database objects.
- Grant roles to users.
- Grant roles to other roles.
User-based Privileges
When a user has privilege requirements that differ from role privileges, you can grant privileges directly to the user. These mechanisms provide data security for many users and classes of users to access the database.
You have the following options for granting privileges:
- Each object privilege can be granted to one or many roles, or to one or many users.
- A role and/or user can be granted privileges on one or many objects.
- A role can be granted to one or many users or other roles.
- A user can be granted one or many roles.
This supports the following many-to-many relationships:
- Objects and roles
- Objects and users
- Roles and users
These relationships provide flexibility and convenience when granting/revoking privileges to and from users.
Granting object privileges to roles and users, and granting roles to users, has a cumulative effect. The result of several grant commands is a combination of all individual grant commands. This applies to all database object types and to privileges inherited by objects. For example, object privileges granted to the object of database type are propagated to all table-type objects of that database object.
Who Can Grant Object Privileges?
Only a superuser or an object owner can grant privileges for on object.
- A superuser has all privileges on all database objects.
- A non-superuser user has only those privileges on a database object that are granted by a superuser.
- A non-superuser user has
ALL
privileges on a table created by that user.
Roles and Privileges Persistence
- Roles can be created and dropped at any time.
- Object privileges and roles can be granted or revoked at any time, and the action takes effect immediately.
- Privilege state is persistent and restored if the OmniSci session is interrupted.
Database Object Privileges
There are four database object types:
- Database
- Table
- View
- Dashboard
Privileges granted on a database-type object are inherited by all tables of that database.
Privilege Commands
SQL | Description |
---|---|
CREATE ROLE | Create role. |
DROP ROLE | Drop role. |
GRANT | Grant role to user or to another role. |
REVOKE | Revoke role from user or from another role. |
GRANT ON TABLE | Grant role privilege(s) on a database table to a role or user. |
REVOKE ON TABLE | Revoke role privilege(s) on database table from a role or user. |
GRANT ON VIEW | Grant role privilege(s) on a database view to a role or user. |
REVOKE ON VIEW | Revoke role privilege(s) on database view from a role or user. |
GRANT ON DATABASE | Grant role privilege(s) on database to a role or user. |
REVOKE ON DATABASE | Revoke role privilege(s) on database from a role or user. |
GRANT ON DASHBOARD | Grant role privilege(s) on dashboard to a role or user. |
REVOKE ON DASHBOARD | Revoke role privilege(s) on dashboard from a role or user. |
Example
The following example shows a valid sequence for granting access privileges to non-superuser user1
by granting a role to user1
and by directly granting a privilege. This example presumes that table1
and user1
already exist, and that user1
has ACCESS privileges on the database where table1
exists.
Create the
r_select
role.CREATE ROLE r_select;
Grant the SELECT privilege on
table1
to ther_select
role. Any user granted ther_select
role gains the SELECT privilege.GRANT SELECT ON TABLE table1 TO r_select;
Grant the
r_select
role touser1
, givinguser1
the SELECT privilege ontable1
.GRANT r_select TO user1;
Directly grant
user1
the INSERT privilege ontable1
.GRANT INSERT ON TABLE table1 TO user1;
See Example Roles and Privileges Session for a more complete example.
CREATE ROLE
Create a role. Roles are granted to users for role-based database object access.
This clause requires superuser privilege and <roleName> must not exist.
DROP ROLE
Remove a role.
This clause requires superuser privilege and <roleName> must exist.
GRANT
Grant role privileges to users and to other roles.
Note | The ACCESS privilege is a prerequisite for all other privileges at the database level. Without the ACCESS privilege, a user or role cannot perform tasks on any other database objects. |
This clause requires superuser privilege. The specified <roleNames> and <userNames> must exist.
Parameters
<roleNames>
Names of roles to grant to users and other roles. Use commas to separate multiple role names.
<userNames>
Names of users. Use commas to separate multiple user names.
REVOKE
Remove role privilege from users or from other roles. This removes database object access privileges granted with the role.
This clause requires superuser privilege. The specified <roleNames> and <userNames> must exist.
Parameters
<roleNames>
Names of roles to remove from users and other roles. Use commas to separate multiple role names.
<userName>
Names of the users. Use commas to separate multiple user names.
Example
Remove payrollDept role privileges from user dennis.
REVOKE payrollDept FROM dennis;
Revoke payrollDept and accountsPayableDept role privileges from users dennis and fred and role hrDept.
REVOKE payrollDept, accountsPayableDept FROM dennis, fred, hrDept;
GRANT ON TABLE
Define the privilege(s) a role or user has on the specified table. You can specify any combination of the INSERT
, SELECT
, DELETE
, UPDATE
, DROP
, or TRUNCATE
privilege or specify all privileges.
Note | The ACCESS privilege is a prerequisite for all other privileges at the database level. Without the ACCESS privilege, a user or role cannot perform tasks on any other database objects. |
This clause requires superuser privilege, or <tableName> must have been created by the user invoking this command. The specified <tableName> and users or roles defined in <entityList> must exist.
Parameters
<privilegeList>
<tableName>
Name of the database table.
Examples
Permit all privileges on the employees
table for the payrollDept role.
GRANT ALL ON TABLE employees TO payrollDept;
Permit SELECT-only privilege on the employees
table for user chris.
GRANT SELECT ON TABLE employees TO chris;
Permit INSERT-only privilege on the employees
table for the hrdept and accountsPayableDept roles.
GRANT INSERT ON TABLE employees TO hrDept, accountsPayableDept;
Permit INSERT, SELECT, and TRUNCATE privileges on the employees
table for the role hrDept and for users dennis and mike.
GRANT INSERT, SELECT, TRUNCATE ON TABLE employees TO hrDept, dennis, mike;
REVOKE ON TABLE
Remove the privilege(s) a role or user has on the specified table. You can remove any combination of the INSERT
, SELECT
, DELETE
, UPDATE
, or TRUNCATE
privileges, or remove all privileges.
This clause requires superuser privilege or <tableName> must have been created by the user invoking this command. The specified <tableName> and users or roles in <entityList> must exist.
Parameters
<privilegeList>
<tableName>
Name of the database table.
Example
Prohibit SELECT and INSERT operations on the employees
table for the nonemployee role.
REVOKE ALL ON TABLE employees FROM nonemployee;
Prohibit SELECT operations on the directors
table for the employee role.
REVOKE SELECT ON TABLE directors FROM employee;
Prohibit INSERT operations on the directors
table for role employee and user laura.
REVOKE INSERT ON TABLE directors FROM employee, laura;
Prohibit INSERT, SELECT, and TRUNCATE privileges on the employees
table for the role nonemployee and for users dennis and mike.
REVOKE INSERT, SELECT, TRUNCATE ON TABLE employees FROM nonemployee, dennis, mike;
GRANT ON VIEW
Define the privileges a role or user has on the specified view. You can specify any combination of the SELECT
, INSERT
, or DROP
privileges, or specify all privileges.
This clause requires superuser privileges, or <viewName> must have been created by the user invoking this command. The specified <viewName> and users or roles in <entityList> must exist.
Examples
Permit SELECT, INSERT, and DROP privileges on the employees
view for the payrollDept role.
GRANT ALL ON VIEW employees TO payrollDept;
Permit SELECT-only privilege on the employees
view for the employee role and user venkat.
GRANT SELECT ON VIEW employees TO employee, venkat;
Permit INSERT and DROP privileges on the employees
view for the hrDept and acctPayableDept roles and users simon and dmitri.
GRANT INSERT, DROP ON VIEW employees TO hrDept, acctPayableDept, simon, dmitri;
REVOKE ON VIEW
Remove the privileges a role or user has on the specified view. You can remove any combination of the INSERT
, DROP
, or SELECT
privileges, or remove all privileges.
This clause requires superuser privilege, or <viewName> must have been created by the user invoking this command. The specified <viewName> and users or roles in <entityList> must exist.
Parameters
<privilegeList>
<viewName>
Name of the database view.
Example
Prohibit SELECT, DROP, and INSERT operations on the employees
view for the nonemployee role.
REVOKE ALL ON VIEW employees FROM nonemployee;
Prohibit SELECT operations on the directors
view for the employee role.
REVOKE SELECT ON VIEW directors FROM employee;
Prohibit INSERT and DROP operations on the directors
view for the employee and manager role and for users ashish and lindsey.
REVOKE INSERT, DROP ON VIEW directors FROM employee, manager, ashish, lindsey;
GRANT ON DATABASE
Define the valid privileges a role or user has on the specified database. You can specify any combination of privileges, or specify all privileges.
Note | The ACCESS privilege is a prerequisite for all other privileges at the database level. Without the ACCESS privilege, a user or role cannot perform tasks on any other database objects. |
This clause requires superuser privileges.
Parameters
<privilegeList>
<dbName>
Name of the database, which must exist, created by CREATE DATABASE.
<entityList>
Name of the entity to be granted the privilege.
Parameter Value | Descriptions |
---|---|
role |
Name of role, which must exist. |
user |
Name of user, which must exist. See Users and Databases. |
Examples
Permit all operations on the companydb
database for the payrollDept role and user david.
GRANT ALL ON DATABASE companydb TO payrollDept, david;
Permit SELECT-only operations on the companydb
database for the employee role.
GRANT ACCESS, SELECT ON DATABASE companydb TO employee;
Permit INSERT, UPDATE, and DROP operations on the companydb
database for the hrdept and manager role and for users irene and stephen.
GRANT ACCESS, INSERT, UPDATE, DROP ON DATABASE companydb TO hrdept, manager, irene, stephen;
REVOKE ON DATABASE
Remove the operations a role or user can perform on the specified database. You can specify privileges individually or specify all privileges.
This clause requires superuser privilege or the user must own the database object. The specified <dbName> and roles or users in <entityList> must exist.
Parameters
<privilegeList>
<dbName>
Example
Prohibit all operations on the employees
database for the nonemployee role.
REVOKE ALL ON DATABASE employees FROM nonemployee;
Prohibit SELECT operations on the directors
database for the employee role and for user monica.
REVOKE SELECT ON DATABASE directors FROM employee;
Prohibit INSERT, DROP, CREATE, and DELETE operations on the directors
database for employee role and for users max and alex.
REVOKE INSERT, DROP, CREATE, DELETE ON DATABASE directors FROM employee;
GRANT ON DASHBOARD
Define the valid privileges a role or user has for working with dashboards. You can specify any combination of privileges or specify all privileges.
This clause requires superuser privileges.
Parameters
<privilegeList>
<dashboardId>
ID of the dashboard, which must exist, created by CREATE DASHBOARD. To show a list of all dashboards and IDs in omnisql, run the \dash
command when logged in as superuser.
<entityList>
Parameter Value | Descriptions |
---|---|
role |
Name of role, which must exist. |
user |
Name of user, which must exist. See Users and Databases. |
Examples
Permit all privileges on the dashboard ID 740
for the payrollDept role.
GRANT ALL ON DASHBOARD 740 TO payrollDept;
Permit VIEW-only privilege on dashboard 730
for the hrDept role and user dennis.
GRANT VIEW ON DASHBOARD 730 TO hrDept, dennis;
Permit EDIT and DELETE privileges on dashboard 740
for the hrDept and accountsPayableDept roles and for user pavan.
GRANT EDIT, DELETE ON DASHBOARD 740 TO hrdept, accountsPayableDept, pavan;
See Also
REVOKE ON DASHBOARD
Remove privileges a role or user has for working with dashboards. You can specify any combination of privileges, or all privileges.
This clause requires superuser privileges.
Parameters
<privilegeList>
Parameter Value | Descriptions |
---|---|
ALL |
Revoke all possible access privileges on <dashboardId> for <entityList>. |
CREATE |
Revoke CREATE privilege for <entityList>. |
DELETE |
Revoke DELETE privilege on <dashboardId> for <entityList>. |
EDIT |
Revoke EDIT privilege on <dashboardId> for <entityList>. |
VIEW |
Revoke VIEW privilege on <dashboardId> for <entityList>. |
<dashboardId>
ID of the dashboard, which must exist, created by CREATE DASHBOARD.
<entityList>
Parameter Value | Descriptions |
---|---|
role |
Name of role, which must exist. |
user |
Name of user, which must exist. See Users and Databases. |
Revoke DELETE privileges on dashboard 740
for the payrollDept role.
REVOKE DELETE ON DASHBOARD 740 FROM payrollDept;
Revoke all privileges on dashboard 730
for hrDept role and users dennis and mike.
REVOKE ALL ON DASHBOARD 730 FROM hrDept, dennis, mike;
Revoke EDIT and DELETE of dashboard 740
for the hrDept and accountsPayableDept roles and for users dante and jonathan.
REVOKE EDIT, DELETE ON DASHBOARD 740 FROM hrdept, accountsPayableDept, dante, jonathan;
Common Privilege Levels for Non-Superusers
The following privilege levels are typically recommended for non-superusers in Immerse. Privileges assigned for users in your organization may vary depending on access requirements.
Example: Roles and Privileges
These examples assume that tables table1
through table4
are created as needed:
create table table1 (id smallint); create table table2 (id smallint); create table table3 (id smallint); create table table4 (id smallint);
The following examples show how to work with users, roles, and tables; dashboards and dashboard privileges work in the same way.
Create User Accounts
create user marketingDeptEmployee1 (password = 'md1');
create user marketingDeptEmployee2 (password = 'md2');
create user marketingDeptManagerEmployee3 (password = 'md3');
create user salesDeptEmployee1 (password = 'sd1');
create user salesDeptEmployee2 (password = 'sd2');
create user salesDeptEmployee3 (password = 'sd3');
create user salesDeptEmployee4 (password = 'sd4');
create user salesDeptManagerEmployee5 (password = 'sd5');
Grant Access to Users on Database
grant access on database omnisci to marketingDeptEmployee1, marketingDeptEmployee2, marketingDeptManagerEmployee3; grant access on database omnisci to salesDeptEmployee1, salesDeptEmployee2, salesDeptEmployee3, salesDeptEmployee4, salesDeptManagerEmployee5;
Grant Marketing Department Roles to Marketing Department Employees
grant marketingDeptRole1 to marketingDeptEmployee1, marketingDeptManagerEmployee3;
grant marketingDeptRole2 to marketingDeptEmployee2, marketingDeptManagerEmployee3;