Calling a stored procedure within a stored procedure
Asked Answered
N

2

3

I am trying to call a function within a function using sql on postgres 9.3.

This question is related to another post by me.

I have written the below function. So far I have failed to incorporate any kind of save-output (COPY) statement, so I am trying to work around this by creating a nested function print-out function.

CREATE FUNCTION retrieve_info(TEXT, TEXT) RETURNS SETOF   
retrieve_info_tbl AS $$
 SELECT tblA.id, tblA.method, tblA.species, tblA.location
 FROM tblA
 WHERE method=$1 AND species=$2
 GROUP BY id, method, species
 ORDER BY location
$$ LANGUAGE 'sql';

The above function works.

An attempt to create a nested function.

CREATE FUNCTION print_out(TEXT, TEXT) RETURNS void AS $$
 COPY (SELECT * FROM retrieve_info($1, $2)) TO 'myfilepath/test.csv'    
 WITH CSV HEADER;
$$ LANGUAGE 'sql';

Calling nested function.

SELECT * FROM print_out('mtd1','sp1');

OUTPUT

The above gives this ERROR: column "$1" does not exist SQL state: 42P02 Context: SQL function "print_out" statement 1. However, when substituting the arg1, arg2 in print_out() with 'mtd1','sp1' the correct output is printed to test.csv (as seen below)

id | method | ind | location
----------------------------
1a | mtd1   | sp3 | locA
1d | mtd1   | sp3 | locB

How would I get the arg1, arg2 of retrieve_info() to call arg1, arg2 properly within print_out()?

I am completely stuck. Would appreciate any pointers, thanks

Nehemiah answered 11/11, 2013 at 23:55 Comment(1)
Closely related: #16020008 and #16991883Arezzo
B
4

COPY is a bit odd as it sort of treats its query argument as a string even though it isn't written as a string. The result is that the query:

SELECT * FROM retrieve_info($1, $2)

isn't executed in the context of the function, it is executed in the context of COPY itself. Even though you say:

copy (select * from t) ...

it is treated more as though you wrote:

copy 'select * from t' ...

so by the time the query is executed, the function parameters no longer have any meaning, the query argument to COPY may look like it would behave like a closure in other languages but it doesn't, it acts more like a string that gets passed to eval.

You can get around this strangeness by using the usual Kludge of Last Resort: dynamic SQL. You should get better results if you write your function to use string wrangling and EXECUTE:

create or replace function print_out(text, text) returns void as $$
begin
    execute 'copy ('
         || 'select * from retrieve_info'
         ||     '(' || quote_literal($1) || ',' || quote_literal($2) || ')'
         || ') to ''myfilepath/test.csv'' with csv header;';
end;
$$ language plpgsql;
Bon answered 14/11, 2013 at 6:5 Comment(11)
Thanks for your answer and explanation. The above above code fails at with csv. Changing it to just ....csv''''; (think I've seen that somewhere) seems to work, but calling it I get the message ERROR: function print_test(unknown, unknown) does not exist SQL state: 42883 Hint: No function matches the given name and argument types. You might need to add explicit type casts. Character: 15Nehemiah
I don't see any print_test anywhere. It worked for me as in my answer, did you mess up the nested quotes somewhere?Bon
Yeah, sorry about that. They are called slightly different in the real code. I think it looks correct(?), please have a look at this print screenNehemiah
You're missing a doubled single quote after "to": ') to '/Users should be ') to ''/Users.Bon
Ah, thanks and thanks for baring with me. However, the nested function doesn't seem to be recognized print screenNehemiah
You're still using this mystery print_test function and I have no way of know what that is or how it is defined. You're defining a print_out function but calling print_test and wondering why it doesn't work.Bon
Ah, yeah. Sorry! Too tired to keep track of the function names yesterday! You're completely right, now it works! Many thanks!!Nehemiah
@Nehemiah You may be interested in format() to simplify string concatenation while automatically quoting values and identifiers. I posted several related answers with more details. Like this one or this oneArezzo
@ErwinBrandstetter: Thanks for the quote fix; I think that might be the first time I've quoted the language and of course you'd spot it.Bon
@Erwin Brandstetter: Thanks, I'll check it out!Nehemiah
You can run, but you cannot hide! ;) Honestly, I was surprised, coming from you ... But then again, if it's any consolation, I caught myself in the act, too. Twice! Copy/paste is a bitch. Anyway, good answer, shenanigans aside.Arezzo
R
0

Are x and y quoted intentionally?

COPY (SELECT * FROM retrieve_info('x','y')) TO 'myfilepath/test.csv'

You are not sending the x and y arguments of print_out to retrieve_info - rather, you are sending the strings 'x' and 'y'. Assuming you don't have records with method='x' AND species='y', it's of little wonder you get no results.

Try this instead:

COPY (SELECT * FROM retrieve_info(x,y)) TO 'myfilepath/test.csv'
Rozanne answered 12/11, 2013 at 2:6 Comment(5)
Thanks your comment. Yes, your right. Stupid of me to leave the quotes (now removed). I've already tested without, but get the this error message after calling the function ERROR: column "x" does not exist SQL state: 42703 Context: SQL function "print_out" statement 1Nehemiah
shouldn't it be @x and @y since they are passed in variables?Ferrite
@Erwin Brandstetter: Since you have been able to help me before, maybe you can give this a shot as well? Do you have any idea how to e.g. add a COPY statement within a function and/or calling a function within a function? Would appreciate any help on this, thanksNehemiah
@Matt: Thanks for your comment. Tried @x,@y, $x,$y and $1, $2 to reference x, y in retrieve_info() but without success...Nehemiah
I have 'undefined' the arguments x, y in trying to make it possible using reference $1, $2Nehemiah

© 2022 - 2024 — McMap. All rights reserved.