Re: Set role dynamically from proc

From: "David G(dot) Johnston" <david(dot)g(dot)johnston(at)gmail(dot)com>
To: Durumdara <durumdara(at)gmail(dot)com>
Cc: "pgsql-general(at)postgresql(dot)org" <pgsql-general(at)postgresql(dot)org>
Subject: Re: Set role dynamically from proc
Date: 2017-11-22 15:28:47
Message-ID: CAKFQuwZKAamsZdNMgmtFwT9Z9LFvCu6w7+O7kbFTXPMmeGHu-w@mail.gmail.com
Views: Raw Message | Whole Thread | Download mbox | Resend email
Thread:
Lists: pgsql-general

On Wed, Nov 22, 2017 at 7:52 AM, Durumdara <durumdara(at)gmail(dot)com> wrote:

> Now the "set role" uses the "variable name", and not the "value of the
> variable".
>
> This is what I don't like in this lang. I need to write a special variable
> name to "force" to use it, and not other thing.
> I don't know how to force the system to use my variable value, and not my
> variable name in the routines.
> For example $var$, or <var>, or [var], etc.
>
> I can generate "set role" with string concat, but in PGAdmin this script
> would be good.
>
>
​There are three kinds of "words" in an SQL command: keywords, identifiers,
​values.

SET ROLE TO davidj;

SET := keyword
ROLE := keyword
TO := keyword
davidj := *identifier*

In pl/pgsql variables can only replace values, not identifiers or
keywords. Since the variable in this case holds an identifier you must use
dynamic SQL to execute the statement you want.

not tested but basically:

EXECUTE format('SET ROLE %I', variablename); --(that's a percent-eye)

More generally when using "PREPARE" at the SQL-level only values can be
replaced with placeholders ($1, $2, etc...). All pl/pgsql is doing when
you use a variable is writing out a PREPARE variation of your command and
the executing it with the variable values as parameter values.

Identifiers are any words that the system is going to lookup in a catalog
(I may be over-simplifying a bit, and the converse, values are not resolved
in a catalog, is generally but possibly not always, true). Identifiers can
always be double-quoted to avoid their case-folding behavior.

David J.

In response to

Responses

Browse pgsql-general by date

  From Date Subject
Next Message Magnus Hagander 2017-11-22 16:24:04 Re: duplicate primary key
Previous Message Adam Brusselback 2017-11-22 14:59:52 [GENERAL] postgres_fdw & could not receive data from client: Connection reset by peer