Thread: Directly embedding a psql SET variable inside another string?

Directly embedding a psql SET variable inside another string?

From
Ron
Date:

Pg 12

I need to pass a \set variable (in this example named v_ssn) into a LIKE string.  A two-stage process (building v_like from v_ssn, and then using v_like in the LIKE string) works, and is fine when executing an sql script, but not so good  is there any way to directly embed v_ssn in another string?

test=# \set v_ssn 345
test=# \echo :v_ssn
345
test=# \set v_like %:v_ssn%
test=# \echo :v_like
%345%

test=# SELECT * FROM employee WHERE ssn LIKE :'v_like';
    ssn    |   name   |  ssn_int  
-----------+----------+-----------
 123456789 | John Doe | 123456789
(1 row)

As expected, this fails:

postgres=# SELECT * FROM employee WHERE ssn LIKE :'%v_ssn%';
ERROR:  syntax error at or near ":"
LINE 1: SELECT * FROM employee WHERE ssn LIKE :'%v_ssn%';


--
Born in Arizona, moved to Babylonia.

Re: Directly embedding a psql SET variable inside another string?

From
Adam Scott
Date:
Do you mean like this?

postgres=# \set v_embed %:v_ssn%
postgres=# \echo :v_embed
%345%
postgres=#  SELECT * FROM employee WHERE ssn LIKE :'v_embed';
    ssn    |   name  
-----------+----------
 123456789 | John Doe
(1 row)



On Fri, Jan 13, 2023 at 8:12 AM Ron <ronljohnsonjr@gmail.com> wrote:

Pg 12

I need to pass a \set variable (in this example named v_ssn) into a LIKE string.  A two-stage process (building v_like from v_ssn, and then using v_like in the LIKE string) works, and is fine when executing an sql script, but not so good  is there any way to directly embed v_ssn in another string?

test=# \set v_ssn 345
test=# \echo :v_ssn
345
test=# \set v_like %:v_ssn%
test=# \echo :v_like
%345%

test=# SELECT * FROM employee WHERE ssn LIKE :'v_like';
    ssn    |   name   |  ssn_int  
-----------+----------+-----------
 123456789 | John Doe | 123456789
(1 row)

As expected, this fails:

postgres=# SELECT * FROM employee WHERE ssn LIKE :'%v_ssn%';
ERROR:  syntax error at or near ":"
LINE 1: SELECT * FROM employee WHERE ssn LIKE :'%v_ssn%';


--
Born in Arizona, moved to Babylonia.

Re: Directly embedding a psql SET variable inside another string?

From
"David G. Johnston"
Date:
On Fri, Jan 13, 2023 at 9:12 AM Ron <ronljohnsonjr@gmail.com> wrote:

is there any way to directly embed v_ssn in another string?

No
As expected, this fails:

postgres=# SELECT * FROM employee WHERE ssn LIKE :'%v_ssn%';
ERROR:  syntax error at or near ":"
LINE 1: SELECT * FROM employee WHERE ssn LIKE :'%v_ssn%';


Two options:

format('%%%s%%', :'v_ssn')
'%' || :'v_ssn' || '%'

David J.

Re: Directly embedding a psql SET variable inside another string?

From
Adrian Klaver
Date:
On 1/13/23 09:08, Adam Scott wrote:
> Do you mean like this?
> 
> postgres=# \set v_embed %:v_ssn%
> postgres=# \echo :v_embed
> %345%
> postgres=#  SELECT * FROM employee WHERE ssn LIKE :'v_embed';
>      ssn    |   name
> -----------+----------
>   123456789 | John Doe
> (1 row)
> 
> 

Actually that replicates what Ron got to work. What Ron is looking for 
is to skip the intermediate step and do:

\set v_ssn 345
SELECT * FROM employee WHERE ssn LIKE :'%v_ssn%';

-- 
Adrian Klaver
adrian.klaver@aklaver.com




Re: Directly embedding a psql SET variable inside another string?

From
"David G. Johnston"
Date:
Please don't top-post.

On Fri, Jan 13, 2023 at 10:08 AM Adam Scott <adam.c.scott@gmail.com> wrote:
Do you mean like this?

postgres=# \set v_embed %:v_ssn%
postgres=# \echo :v_embed
 
test=# \set v_like %:v_ssn%
test=# \echo :v_like


Aside from the names those look identical...

David J.

Re: Directly embedding a psql SET variable inside another string?

From
Ron
Date:
On 1/13/23 11:13, David G. Johnston wrote:
On Fri, Jan 13, 2023 at 9:12 AM Ron <ronljohnsonjr@gmail.com> wrote:

is there any way to directly embed v_ssn in another string?

No
As expected, this fails:

postgres=# SELECT * FROM employee WHERE ssn LIKE :'%v_ssn%';
ERROR:  syntax error at or near ":"
LINE 1: SELECT * FROM employee WHERE ssn LIKE :'%v_ssn%';


Two options:

format('%%%s%%', :'v_ssn')

This one looks clean, and works perfectly:

'%' || :'v_ssn' || '%'

--
Born in Arizona, moved to Babylonia.