Thread: scope quirk in copy in function

scope quirk in copy in function

From
Scott Ribe
Date:
create or replace function archive_some_stuff() returns void as $$
declare cutoff timestamptz;
begin
  cutoff := now() - '1 day'::interval;
  copy (select * from log where end_when < cutoff) to ...
  ...

Gives me an error that there is column named cutoff. (Other uses of cutoff in queries not inside a copy, iow the delete
fromcommands, work.) 

Is there any alternative to just duplicating the now() expression inside every copy?

--
Scott Ribe
scott_ribe@elevated-dev.com
http://www.elevated-dev.com/
https://www.linkedin.com/in/scottribe/
(303) 722-0567 voice







Re: scope quirk in copy in function

From
Adrian Klaver
Date:
On 03/23/2015 06:59 AM, Scott Ribe wrote:
> create or replace function archive_some_stuff() returns void as $$
> declare cutoff timestamptz;
> begin
>    cutoff := now() - '1 day'::interval;
>    copy (select * from log where end_when < cutoff) to ...
>    ...
>
> Gives me an error that there is column named cutoff. (Other uses of cutoff in queries not inside a copy, iow the
deletefrom commands, work.) 
>
> Is there any alternative to just duplicating the now() expression inside every copy?

http://www.postgresql.org/docs/9.3/interactive/plpgsql-implementation.html#PLPGSQL-VAR-SUBST

"Variable substitution currently works only in SELECT, INSERT, UPDATE,
and DELETE commands, because the main SQL engine allows query parameters
only in these commands. To use a non-constant name or value in other
statement types (generically called utility statements), you must
construct the utility statement as a string and EXECUTE it."

>


--
Adrian Klaver
adrian.klaver@aklaver.com


Re: scope quirk in copy in function

From
Tom Lane
Date:
Adrian Klaver <adrian.klaver@aklaver.com> writes:
> On 03/23/2015 06:59 AM, Scott Ribe wrote:
>> create or replace function archive_some_stuff() returns void as $$
>> declare cutoff timestamptz;
>> begin
>> cutoff := now() - '1 day'::interval;
>> copy (select * from log where end_when < cutoff) to ...

> "Variable substitution currently works only in SELECT, INSERT, UPDATE,
> and DELETE commands, because the main SQL engine allows query parameters
> only in these commands. To use a non-constant name or value in other
> statement types (generically called utility statements), you must
> construct the utility statement as a string and EXECUTE it."

Yeah.  It seems like SELECT-inside-COPY might be worth special casing
though.  ISTM this is more or less analogous to the case of PREPARE or
DECLARE CURSOR, which are also utility commands that contain a regular DML
command.  I'm pretty sure there is a hack in there that allows parameters
to be transmitted down through PREPARE or D.C. ...

            regards, tom lane