GRANT SELECT ON TABLE CATALOG.SCHEMA.T1 TO SALES WHERE SALES_REGION = 'NORTHEAST'
SELECT
* FROM T1
, the query is effectively transformed to SELECT
* FROM T1 WHERE SALES_REGION = 'NORTHEAST'
.
GRANT SELECT ON TABLE CATALOG.SCHEMA.T1 TO SALES WHERE SYSCAT.RLS.CURRENT_USER() = \"USER NAME\"
SELECT * FROM
T1
, the query is transformed to:
SELECT * FROM T1 WHERE 'BOB' = "USER NAME"
Example: RLS Predicate Union
In this example USER is a direct member of the user-defined groups GROUP1, GROUP2
and GROUP4. USER is also a member of the two built in groups, SASUSERS and PUBLIC.
The RLS query returned for USER is (RLS1 OR RLS4 OR RLS3).
Note: Blue nodes contain a conditional
privilege; gray nodes contain NO privilege.
|
The first predicate, RLS1, is encountered at level 1 in the graph, so the remaining
RLS predicates are captured at that level for the current graph, which does not include
the secondary graphs, SASUSERS and PUBLIC. The GROUP1 node is marked as visited, and
its parent (“member of”) associations will not be navigated since it contributed a
predicate.
After marking it as
visited, the procedure skips GROUP2 since it has no assigned privileges
and proceeds to GROUP4 where the node is marked as visited and RLS4
is captured and combined to the query using an OR operator. There
are no more nodes at level 1, so the procedure continues with the
parent associations of GROUP2.
GROUP3 is marked as visited and predicate RLS3 is captured and combined to the query
using an OR operator. The privilege has been satisfied at this point because an RLS
query is available. The two graphs starting at SASUSERS and PUBLIC are not searched.
The resulting RLS query is:
RLS1 OR RLS4 OR RLS3 .
|
SELECT SYSCAT.RLS.RLS_function('name').
For
example:
SELECT SYSCAT.RLS.group_id('GROUP1')
SYSCAT.RLS.RLS_function
.
Following are the callable functions for row-level security.
Returns the authentication provider identifier for the specified user or group name.
Returns the name of the current user.
Returns an opaque authentication provider specific user identifier.
Returns the name of the domain in which the current user is authenticated.
Returns the authentication provider group identifier for the specified group name.
Returns the domain-qualified user id that is used to authenticate the current user.
Returns the SANs domain user id that is used to authenticate the current user. Note that the userid function is similar to the login function, but it is not domain-qualified.
Returns the client IP address of the current user’s session.
Returns TRUE or FALSE indicating if the current user is an administrator.
Returns TRUE or FALSE indicating if the current user is the process user.
Returns TRUE or FALSE indicating if the current user is a member of the specified group.
Returns a single group name or result set identifying the group memberships of the current user.
current_user
and member_of
to
qualify users for SELECT on specific rows in the HR.EMPLOYEES table. grant SELECT on HR.EMPLOYEES to SASUSERS where (syscat.rls.current_user() in ("Name","MgrName")) or syscat.rls.member_of("Payroll",'DEEP')
Returns an authentication identifier as defined by the authentication provider, as a result of passing input for user name.
Returns the name of the current user. This is the authorization identifier of the currently authenticated user, rather than the login used.
Returns a user identifier as defined by the authentication provider. Typically, this is a static identifier by which the current user is known. Applications can associate this identifier with an internal organization user identifier such as an employee number or account number.
The name of the domain in which the current user is authenticated.
Returns a group identifier as defined by the authentication provider, as a result of passing input for group name
The login used to authenticate the current user.
The domain qualified user ID. If the upn parameter is TRUE, the format of the returned user ID is user@domain. Otherwise, the format is domain\user on Windows systems and just userid on all other systems. The userid function returns the authenticated user ID as specified by the authentication service. The authentication service can reside on a different host
Returns the client IP address of the current user’s session.
Returns TRUE or FALSE if the current user is or is not an administrator.
Returns TRUE or FALSE if the current user is, or is not the process user.
Returns TRUE or FALSE if the current user is, or is not a member of the specified group. Can assert direct or indirect membership. The group parameter is a group name by default and a group identifier if the ‘ID’ or 'DEEP' option is present in the options string. The options string is a blank or comma separated string consisting of one or more of ‘ID’ and ‘DEEP’ option keywords. The current user must be a direct member of the specified group unless the ‘DEEP’ keyword is specified. ‘DEEP’ checks for both direct and indirect group membership. Direct membership is tested by default.
Returns a single group name or identifier column result set containing the current user’s group memberships. The available options are ‘ID’ or ‘DEEP’. Can be restricted to direct memberships only. The authorization parameter is a user or group name by default and a user or group identifier if the 'ID' option is present in the options string. The options string is a blank or comma separated string consisting of one or more of ‘ID’ and ‘DEEP’ option keywords. A deep group membership listing is returned if the ‘DEEP’ keyword is specified, the default being a shallow listing.
member_of
and groups
RLS functions. Consider the following queries:
SYSCAT.RLS.GROUPS(user_name_or_id [, options])
user_name_or_id
.
SYSCAT.RLS.MEMBER_OF(group_name_or_id [, options])
group_name_or_id
.
user_name_or_id
returns
a string literal indicating the user name or user ID. If options
contains
‘ID’, the argument is treated as a user ID ('6C6C9AD1E2646F0469DD6A3D1874D167')
rather than a user name ('USER1').
group_name_or_ID
returns
a string literal indicating the group name or group ID. If options
contains
‘ID’, the argument is treated as a group ID ('78319AD1E2646F0469DD6A3D1874A2F7')
rather than a group name ('GROUP1').
options
returns
a string literal containing 'GROUP', 'ID', or
both ( 'GROUP, ID'). If multiple options are specified,
they can be separated in the string by a blank in single quotation
marks (' ') or comma in single quotation marks (',').
If options
contains 'ID' the argument
is treated as an ID rather than a name. If options
contains
‘DEEP’, group membership is checked for direct and indirect
membership.
Select SYSCAT.RLS.GROUP_ID('GROUP1')
'BEA892C6D4A40464C8A144D89FFE6463'
Select SYSCAT.RLS.GROUP_ID('GROUP2')
'45C562900C7333C49B1706B38DBA75B0'
Select SYSCAT.RLS.CURRENT_ID()
'5790EE3F6A24A7349AA2254600793411'
for
USER1
Select SYSCAT.RLS.MEMBER_OF('GROUP1')
TRUE
for
USER1.
Select SYSCAT.RLS.MEMBER_OF('GROUP2')
FALSE
for
USER1.
Select SYSCAT.RLS.MEMBER_OF('GROUP2',
'DEEP')
TRUE
for
USER1.
Select SYSCAT.RLS.MEMBER_OF('BEA892C6D4A40464C8A144D89FFE6463',
'ID')
FALSE
for
USER1.
Select SYSCAT.RLS.MEMBER_OF('45C562900C7333C49B1706B38DBA75B0',
'ID')
TRUE
for
USER1.
Select SYSCAT.RLS.MEMBER_OF('BEA892C6D4A40464C8A144D89FFE6463',
'DEEP, ID')
TRUE
for
USER1.
GROUPS
function which returns a result set:
Select * from SYSCAT.RLS.GROUPS('USER1')
"GROUP" 'SASUSERS' 'GROUP1' 'PUBLIC'
Select * from SYSCAT.RLS.GROUPS('USER1',
'DEEP')
"GROUP" 'SASUSERS' 'GROUP1' 'GROUP2' 'PUBLIC'