Chapter 6. Access Control

Fred Toussi

The HSQL Development Group

$Revision: 3096 $

Copyright 2010 Fred Toussi. Permission is granted to distribute this document without any alteration under the terms of the HSQLDB license. Additional permission is granted to the HSQL Development Group to distribute this document with or without alterations under the terms of the HSQLDB license.

$Date: 2009-08-09 17:50:39 +0100 (Sun, 09 Aug 2009) $

Table of Contents

Overview
Authorizations and Access Control
Built-In Roles and Users
Access Rights
Statements for Authorization and Access Control

Overview

Apart from schemas and their object, each HyperSQL catalog has USER and ROLE objects. These objects are collectively called authorizations. Each AUTHORIZATION has some access rights on some of the schemas or the objects they contain. The persistent elements of an SQL environment are database objects

Each database object has a name. A name is an identifier and is unique within its name-space. Authorizations names follow the rules described below and the case-normal form is stored in the database. When connecting to a database, the user name and password must match the case of the case-normal form.

identifier

definition of identifier

<identifier> ::= <regular identifier> | <delimited identifier> | <SQL language identifier>

<delimited identifier> ::= <double quote> <character sequence> <double quote>

<regular identifier> ::= <special character sequence>

<SQL language identifier> ::= <special character sequence>

A <delimited identifier> is a sequence of characters enclosed with double-quote symbols. All characters are allowed in the character sequence.

A <regular identifier> is a special sequence of characters. It consists of letters, digits and the underscore characters. It must begin with a letter.

A <SQL language identifier> is similar to <regular identifier> but the letters can range only from A-Z in the ASCII character set. This type of identifier is used for names of CHARACTER SET objects.

If the character sequence of a delimited identifier is the same as an undelimited identifier, it represents the same identifier. For example "JOHN" is the same identifier as JOHN. In a <regular identifier> the case-normal form is considered for comparison. This form consists of the upper-case of equivalent of all the letters.

The character sequence length of all identifiers must be between 1 and 128 characters.

A reserved word is one that is used by the SQL Standard for special purposes. It is similar to a <regular identifier> but it cannot be used as an identifier for user objects. If a reserved word is enclosed in double quote characters, it becomes a quoted identifier and can be used for database objects.

Authorizations and Access Control

In general, ROLE and USER objects simply control access to schema objects. This is the scope of the SQL Standard. However, there are special roles that allow the creation of USER and ROLE objects and also allow some special operations on the database as a whole. These roles are not defined by the Standard, which has left it to implementors to define such roles as they are needed for the particular SQL implementation.

A ROLE has a name a collection of zero or more other roles, plus some privileges (access rights). A USER has a name and a password. It similarly has a collection of zero or more roles plus some privileges.

USER objects existed in the SQL-92, but ROLE objects were introduced in SQL:1999. Originally it was intended that USER objects would normally be the same as the operating system USER objects and their authentication would be handled outside the SQL environment. The co-existence of ROLE and USER objects results in complexity. With the addition of ROLE objects, there is no rationale, other than legacy support, for granting privileges to USER objects directly. It is better to create roles and grant privileges to them, then grant the roles to USER objects.

The Standard effectively defines a special ROLE, named PUBLIC. All authorization have the PUBLIC role, which cannot be removed from them. Therefore any access right assigned to the PUBLIC role applies to all authorizations in the database. For many simple databases, it is adequate to create a single, non-admin user, then assign access rights to the pre-existing PUBLIC role. Access to INFORMATION_SCHEMA views is granted to PUBLIC, therefore these views are accessible to all. However, the contents of each view depends on the ROLE or USER (AUTHORIZATION) that is in force while accessing the view.

Each schema has a single AUTHORIZATION. This is commonly known as the owner of the schema. All the objects in the schema inherit the schema owner. The schema owner can add objects to the schema, drop them or alter them.

By default, the objects in a schema can only be accessed by the schema owner. The schema owner can grant access rights on the objects to other users or roles.

authorization identifier

authorization identifier

<authorization identifier> ::= <role name> | <user name>

Authorization identifiers share the same name-space within the database. The same name cannot be used for a USER and a ROLE.

Built-In Roles and Users

There are some pre-defined roles in each database; some defined by the SQL Standard, some by HyperSQL. These roles can be assigned to users (directly or via other, user-defined roles). In addition, there is the default initial user, SA, created with each new database.

PUBLIC

the PUBLIC role

The role that is assigned to all authorizations (roles and users) in the database. This role has access rights to all objects in the INFORMATION_SCHEMA. Any roles or rights granted to this role, are in effect granted to all users of the database.

_SYSTEM

the _SYSTEM role

This role is the authorization for the pre-defined (system) objects in the database, including the INFORMATION_SCHEMA. This role cannot be assigned to any authorization.

DBA

the DBA role (HyperSQL-specific)

This is a special role in HyperSQL. A user that has this role can perform all possible administrative tasks on the database. The DBA role can also act as a proxy for all the roles and users in the database. This means it can do everything the authorization for a schema can do, including dropping the schema or its objects, or granting rights on the schema objects to a grantee.

CREATE_SCHEMA

the CREATE_SCHEMA role (HyperSQL-specific)

An authorization that has this role, can create schemas. The DBA authorization has this role and can grant it to other authorizations.

CHANGE_AUTHORIZATION

the CHANGE_AUTHORIZATION role (HyperSQL-specific)

A user that has this role, can change the authorization for the current session to another user. The DBA authorization has this role and can grant it to other authorizations.

SA

the SA user (HyperSQL-specific)

This user is automatically created with a new database and has the DBA role. Initially, the password for this user is an empty string. After connecting to the new database as this user, it is possible to change the password, create other users and created new schema objects. The SA user can be dropped by another user that has the DBA role.

Access Rights

By default, the objects in a schema can only be accessed by the schema owner. But the schema owner can grant privileges (access rights) on the objects to other users or roles.

Things can get far more complex, because the grant of privileges can be made WITH GRANT OPTION. In this case, the role or user that has been granted the privilege can grant the privilege to other roles and users.

Privileges can also be revoked from users or roles.

The statements for granting and revoking privileges normally specify which privileges are granted or revoked. However, there is a shortcut, ALL PRIVILEGES, which means all the privileges that the <grantor> has on the schema object. The <grantor> is normally the CURRENT_USER of the session that issues the statement.

The user or role that is granted privileges is referred to as <grantee> for the granted privileges.

Table

For tables, including views, privileges can be granted with different degrees of granularity. It is possible to grant a privilege on all columns of a table, or on specific columns of the table.

The DELETE privilege applies to the table, rather than its columns. It applies to all DELETE statements.

The SELECT, INSERT and UPDATE privileges may apply to all columns or to individual columns. These privileges determine whether the <grantee> can execute SQL data statements on the table.

The SELECT privilege designates the columns that can be referenced in SELECT statements, as well as the columns that are read in a DELETE or UPDATE statement, including the search condition.

The INSERT privilege designates the columns into which explicit values can be inserted. To be able to insert a row into the table, the user must therefore have the INSERT privilege on the table, or at least all the columns that do not have a default value.

The UPDATE privilege simply designates the table or the specific columns that can be updated.

The REFERENCES privilege allows the <grantee> to define a FOREIGN KEY constraint on a different table, which references the table or the specific columns designated for the REFERENCES privilege.

The TRIGGER privilege allows adding a trigger to the table.

Sequence, Type, Domain, Character Set, Collation, Transliteration,

For these objects, only USAGE can be granted. The USAGE privilege is needed when object is referenced directly in an SQL statement.

Routine

For routines, including procedures or functions, only EXECUTE privilege can be granted. This privilege is needed when the routine is used directly in an SQL statement.

Other Objects

Other objects such as constraints and assertions are not used directly and there is no grantable privilege that refers to them.

Statements for Authorization and Access Control

The statements listed below allow creation and destruction of USER and ROLE objects. The GRANT and REVOKE statements allow roles to be assigned to other roles or to users. The same statements are also used in a different form to assign privileges on schema objects to users and roles.

CREATE USER

user definition (HyperSQL)

<user definition> ::= CREATE USER <user name> PASSWORD <password> [ ADMIN ]

Define a new user and its password. <user name> is an SQL identifier. If it is double-quoted it is case-sensitive, otherwise it is turned to uppercase. <password> is a string enclosed with single quote characters and is case-sensitive. If ADMIN is specified, the DBA role is granted to the new user. Only a user with the DBA role can execute this statement.

DROP USER

drop user statement (HyperSQL)

<drop user statement> ::= DROP USER <user name>

Drop (destroy) an existing user. If the specified user is the authorization for a schema, the schema is destroyed. Only a user with the DBA role can execute this statement.

ALTER USER ... SET PASSWORD

set the password for a user (HyperSQL)

<alter user set password statement> ::= ALTER USER <user name> SET PASSWORD <password>

Change the password of an existing user. <user name> is an SQL identifier. If it is double-quoted it is case-sensitive, otherwise it is turned to uppercase. <password> is a string enclosed with single quote characters and is case-sensitive. Only a user with the DBA role can execute this command.

ALTER USER ... SET INITIAL SCHEMA

set the initial schema for a user (HyperSQL)

<alter user set initial schema statement> ::= ALTER USER <user name> SET INITIAL SCHEMA <schema name> | DEFAULT

Change the initial schema for a user. The initial schema is the schema used by default for SQL statements issued during a session. If DEFAULT is used, the default initial schema for all users is used as the initial schema for the user. The SET SCHEMA command allows the user to change the schema for the duration of the session. Only a user with the DBA role can execute this statement.

SET PASSWORD

set password statement (HyperSQL)

<set password statement> ::= SET PASSWORD <password>

Set the password for the current user. <password> is a string enclosed with single quote characters and is case-sensitive.

SET INITIAL SCHEMA

set the initial schema for the current user (HyperSQL)

<set initial schema statement> ::= SET INITIAL SCHEMA <schema name> | DEFAULT

Change the initial schema for the current user. The initial schema is the schema used by default for SQL statements issued during a session. If DEFAULT is used, the default initial schema for all users is used as the initial schema for the current user. The separate SET SCHEMA command allows the user to change the schema for the duration of the session. See also the Sessions and Transactions chapter.

SET DATABASE DEFAULT INITIAL SCHEMA

set the default initial schema for all users (HyperSQL)

<set database default initial schema statement> ::= SET DATABASE DEFAULT INITIAL SCHEMA <schema name>

Sets the initial schema for new users. This schema can later be changed with the <set initial schema statement> command.

CREATE ROLE

role definition

<role definition> ::= CREATE ROLE <role name> [ WITH ADMIN <grantor> ]

Defines a new role. Initially the role has no rights, except those of the PUBLIC role. Only a user with the DBA role can execute this command.

DROP ROLE

drop role statement

<drop role statement> ::= DROP ROLE <role name>

Drop (destroy) a role. If the specified role is the authorization for a schema, the schema is destroyed. Only a user with the DBA role can execute this statement.

GRANTED BY

grantor determination

GRANTED BY <grantor>

<grantor> ::= CURRENT_USER | CURRENT_ROLE

The authorization that is granting or revoking a role or privileges. The optional GRANTED BY <grantor> clause can be used in various statements that perform GRANT or REVOKE actions. If the clause is not used, the authorization is CURRENT_USER. Otherwise, it is the specified authorization.

GRANT

grant privilege statement

<grant privilege statement> ::= GRANT <privileges> TO <grantee> [ { <comma> <grantee> }... ] [ WITH GRANT OPTION ] [ GRANTED BY <grantor> ]

Assign privileges on schema objects to roles or users. Each <grantee> is a role or a user. If [ WITH GRANT OPTION ] is specified, then the <grantee> can assign the privileges to other <grantee> objects.

<privileges> ::= <object privileges> ON <object name>

<object name> ::= [ TABLE ] <table name> | DOMAIN <domain name> | COLLATION <collation name> | CHARACTER SET <character set name> | TRANSLATION <transliteration name> | TYPE <user-defined type name> | SEQUENCE <sequence generator name> | <specific routine designator> | ROUTINE <routine name> | FUNCTION <function name> | PROCEDURE <procedure name>

<object privileges> ::= ALL PRIVILEGES | <action> [ { <comma> <action> }... ]

<action> ::= SELECT | SELECT <left paren> <privilege column list> <right paren> | DELETE | INSERT [ <left paren> <privilege column list> <right paren> ] | UPDATE [ <left paren> <privilege column list> <right paren> ] | REFERENCES [ <left paren> <privilege column list> <right paren> ] | USAGE | TRIGGER | EXECUTE

<privilege column list> ::= <column name list>

<grantee> ::= PUBLIC | <authorization identifier>

The <object privileges> that can be used depend on the type of the <object name>. These are discussed in the previous section. For a table, if <privilege column list> is not specified, then the privilege is granted on the table, which includes all of its columns and any column that may be added to it in the future. For routines, the name of the routine can be specified in two ways, either as the generic name as the specific name. HyperSQL allows referencing all overloaded versions of a routine at the same time, using its name. This differs from the SQL Standard which requires the use of <specific routine designator> to grant privileges separately on each different signature of the routine.

Each <grantee> is the name of a role or a user. Examples of GRANT statement are given below:

GRANT ALL ON SEQUENCE aSequence TO roleOrUser 
GRANT SELELCT ON aTable TO roleOrUser  
GRANT SELECT, UPDATE ON aTABLE TO roleOrUser1, roleOrUser2
GRANT SELECT(columnA, columnB), UPDATE(columnA, columnB) ON TABLE aTable TO roleOrUser
GRANT EXECUTE ON SPECIFIC ROUTINE aroutine_1234 TO rolOrUser

As mentioned in the general discussion, it is better to define a role for the collection of all the privileges required by an application. This role is then granted to any user. If further changes are made to the privileges of this role, they are automatically reflected in all the users that have the role.

GRANT

grant role statement

<grant role statement> ::= GRANT <role name> [ { <comma> <role name> }... ] TO <grantee> [ { <comma> <grantee> }... ] [ WITH ADMIN OPTION ] [ GRANTED BY <grantor> ]

Assign roles to roles or users. One or more roles can be assigned to one or more <grantee> objects. A <grantee> is a user or a role. If the [ WITH ADMIN OPTION ] is specified, then each <grantee> can grant the newly assigned roles to other grantees. An example of user and role creation with grants is given below:

CREATE USER appuser
CREATE ROLE approle
GRANT approle TO appuser
GRANT SELECT, UPDATE ON TABLE atable TO approle
GRANT USAGE ON SEQUENCE asequence to approle
GRANT EXECUTE ON ROUTINE aroutine TO approle

REVOKE privilege

revoke statement

<revoke privilege statement> ::= REVOKE [ GRANT OPTION FOR ] <privileges> FROM <grantee> [ { <comma> <grantee> }... ] [ GRANTED BY <grantor> ] RESTRICT | CASCADE

Revoke privileges from a user or role.

REVOKE role

revoke role statement

<revoke role statement> ::= REVOKE [ ADMIN OPTION FOR ] <role revoked> [ { <comma> <role revoked> }... ] FROM <grantee> [ { <comma> <grantee> }... ] [ GRANTED BY <grantor> ] RESTRICT | CASCADE

<role revoked> ::= <role name>

Revoke a role from users or roles.


$Revision: 3601 $