Connecting as another user without their password

Post date: Jan 15, 2016 8:41:29 AM

In Oracle we use to run (from privileged user)

alter session set current_schema=abc;

Lets discuss how we can achieve same thing in Greenplum using SET ROLE and with SET SESSION AUTHORIZATION.

SET ROLE command sets the current role identifier of the current session.

This command sets the current role identifier of the current SQL-session context to be rolename. The role name may be written as either an identifier or a string literal. After SET ROLE, permissions checking for SQL commands is carried out as though the named role were the one that had logged in originally.

The specified rolename must be a role that the current session user is a member of. If the session user is a superuser, any role can be selected. The NONE and RESET forms reset the current role identifier to be the current session role identifier. These forms may be executed by any user.

Parameters SESSION - Specifies that the command takes effect for the current session. This is the default.LOCAL -Specifies that the command takes effect for only the current transaction. After COMMIT or ROLLBACK, the session-level setting takes effect again. Note that SET LOCAL will appear to have no effect if it is executed outside of a transaction.

rolename -The name of a role to us -e for permissions checking in this session. NONE and RESET Reset the current role identifier to be the current session role identifier (that of the role used to log in).

Using this command, it is possible to either add privileges or restrict privileges. If the session user role has the INHERITS attribute, then it automatically has all the privileges of every role that it could SET ROLE to; in this case SET ROLE effectively drops all the privileges assigned directly to the session user and to the other roles it is a member of, leaving only the privileges available to the named role. On the other hand, if the session user role has the NOINHERITS attribute, SET ROLE drops the privileges assigned directly to the session user and instead acquires the privileges available to the named role.

In particular, when a superuser chooses to SET ROLE to a non-superuser role, she loses her superuser privileges.

SET ROLE has effects comparable to SET SESSION AUTHORIZATION, but the privilege checks involved are quite different. Also, SET SESSION AUTHORIZATION determines which roles are allowable for later SET ROLE commands, whereas changing roles with SET ROLE does not change the set of roles allowed to a later SET ROLE.

Examples

gpadmin=# SELECT SESSION_USER, CURRENT_USER;

 session_user | current_user 

--------------+--------------

 gpadmin      | gpadmin

(1 row)

gpadmin=# SET ROLE 'sachi';

SET

gpadmin=> SELECT SESSION_USER, CURRENT_USER;

 session_user | current_user 

--------------+--------------

 gpadmin      | sachi

(1 row)

gpadmin=> 

Another way of doing this and little extra is with SET SESSION AUTHORIZATION command.

SET SESSION AUTHORIZATION command sets the session role identifier and the current role identifier of the current session.

Synopsis

SET [SESSION | LOCAL] SESSION AUTHORIZATION rolename

SET [SESSION | LOCAL] SESSION AUTHORIZATION DEFAULT

RESET SESSION AUTHORIZATION

Description

This command sets the session role identifier and the current role identifier of the current SQL-session context to be rolename. The role name may be written as either an identifier or a string literal. Using this command, it is possible, for example, to temporarily become an unprivileged user and later switch back to being a superuser.The session role identifier is initially set to be the (possibly authenticated) role name provided by the client. The current role identifier is normally equal to the session user identifier, but may change temporarily in the context of setuid functions and similar mechanisms; it can also be changed by SET ROLE. The current user identifier is relevant for permission checking.

The session user identifier may be changed only if the initial session user (the authenticated user) had the superuser privilege. Otherwise, the command is accepted only if it specifies the authenticated user name.

The DEFAULT and RESET forms reset the session and current user identifiers to be the originally authenticated user name. These forms may be executed by any user.

Parameters

SESSION

Specifies that the command takes effect for the current session. This is the default.

LOCAL

Specifies that the command takes effect for only the current transaction. After COMMIT or ROLLBACK, the session-level setting takes effect again. Note that SET LOCAL will appear to have no effect if it is executed outside of a transaction.

rolename

The name of the role to assume.

NONE

RESET

Reset the session and current role identifiers to be that of the role used to log in.

Examples

gpadmin=# SELECT SESSION_USER, CURRENT_USER;

 session_user | current_user 

--------------+--------------

 gpadmin      | gpadmin

(1 row)

gpadmin=# SET ROLE 'sachi';

SET

gpadmin=> SELECT SESSION_USER, CURRENT_USER;

 session_user | current_user 

--------------+--------------

 gpadmin      | sachi

(1 row)

gpadmin=> SET ROLE NONE;

SET

gpadmin=# SELECT SESSION_USER, CURRENT_USER;

 session_user | current_user 

--------------+--------------

 gpadmin      | gpadmin

(1 row)

gpadmin=# SET SESSION AUTHORIZATION 'sachi';

SET

gpadmin=> SELECT SESSION_USER, CURRENT_USER;

 session_user | current_user 

--------------+--------------

 sachi        | sachi

(1 row)

gpadmin=>