The SET ROLE statement allows you to set the current role for the current SQL context of a session.
You can set a role only if the current user has been granted the role, or if the role has been granted to PUBLIC.
For more information on roles, see "Using SQL roles" in the Derby Developer's Guide.
SET ROLE { roleName | 'stringConstant' | ? | NONE }
If you specify a roleName of NONE, the effect is to unset the current role.
If you specify the role as a string constant or as a dynamic parameter specification (?), any leading and trailing blanks are trimmed from the string before attempting to use the remaining (sub)string as a roleName. The dynamic parameter specification can be used in prepared statements, so the SET ROLE statement can be prepared once and then executed with different role values. You cannot specify NONE as a dynamic parameter.
Setting a role identifies a set of privileges that is a union of the following:
In a session, the current privileges define what the session is allowed to access. The current privileges are the union of the following:
The SET ROLE statement is not transactional; a rollback does not undo the effect of setting a role. If a transaction is in progress, an attempt to set a role results in an error.
SET ROLE reader;
// These examples show the use of SET ROLE in JDBC statements. // The case normal form is visible in the SYS.SYSROLES system table. stmt.execute("SET ROLE admin"); -- case normal form: ADMIN stmt.execute("SET ROLE \"admin\""); -- case normal form: admin stmt.execute("SET ROLE none"); -- special case PreparedStatement ps = conn.prepareStatement("SET ROLE ?"); ps.setString(1, " admin "); -- on execute: case normal form: ADMIN ps.setString(1, "\"admin\""); -- on execute: case normal form: admin ps.setString(1, "none"); -- on execute: syntax error ps.setString(1, "\"none\""); -- on execute: case normal form: none