Thread: How to avoid nulls while writing string for dynamic query
Dear Friends,
Postgres 7.3.4 on RH Linux 7.2.
I wanted to write a dynamic query for insert statement.
create table test(c1 int, c2 varchar)
insert into test(c1, c2) values (1,'Hai1');
insert into test(c1, c2) values (NULL,'Hai2');
insert into test(c1, c2) values (NULL,'Hai2');
so I wrote a function called test_fn()
DECLARE
sqlstr VARCHAR(100);
rec RECORD;
BEGIN
FOR rec IN SELECT * FROM test
LOOP
sqlstr := 'insert into test(c1, c2) values (' ||rec.c1||','
||'\''||rec.c2||'\')';
RAISE NOTICE '%',sqlstr;
execute sqlstr;
END LOOP;
RETURN 'DONE';
END;
sqlstr VARCHAR(100);
rec RECORD;
BEGIN
FOR rec IN SELECT * FROM test
LOOP
sqlstr := 'insert into test(c1, c2) values (' ||rec.c1||','
||'\''||rec.c2||'\')';
RAISE NOTICE '%',sqlstr;
execute sqlstr;
END LOOP;
RETURN 'DONE';
END;
NOTICE: insert into test(c1, c2) values (1,'Hai1')
NOTICE: <NULL>
NOTICE: <NULL>
So i have created a null function.
sqlstr := 'insert into test(c1, c2) values (' ||ISNULL(rec.c1,'')||','
||'\''||rec.c2||'\')';
||'\''||rec.c2||'\')';
Now I got results as
NOTICE: insert into test(c1, c2) values (1,'Hai1')
NOTICE: insert into test(c1, c2) values (,'Hai2')
WARNING: Error occurred while executing PL/pgSQL function test_fn
WARNING: line 11 at execute statement
NOTICE: insert into test(c1, c2) values (,'Hai2')
WARNING: Error occurred while executing PL/pgSQL function test_fn
WARNING: line 11 at execute statement
ERROR: parser: parse error at or near "," at character 34
The error is because of no value for column c1. If the column c1 is a string I might have replace it with empty string. I don't want to substitute with '0' which could work.
sqlstr := 'insert into test(c1, c2) values (' ||ISNULL(rec.c1,'0')||','
||'\''||rec.c2||'\')';
||'\''||rec.c2||'\')';
NOTICE: insert into test(c1, c2) values (1,'Hai1')
NOTICE: insert into test(c1, c2) values (0,'Hai2')
NOTICE: insert into test(c1, c2) values (0,'Hai2')
Total query runtime: 47 ms.
Data retrieval runtime: 0 ms.
1 rows retrieved.
Data retrieval runtime: 0 ms.
1 rows retrieved.
How can I do that. Please advise me.
Thanks
Kumar
Dnia 2004-02-12 13:31, Użytkownik Kumar napisał: > The error is because of no value for column c1. If the column c1 is a > string I might have replace it with empty string. I don't want to > substitute with '0' which could work. > > sqlstr := 'insert into test(c1, c2) values (' ||ISNULL(rec.c1,'0')||',' > > ||'\''||rec.c2||'\')'; Substitute it with NULL value: sqlstr := 'insert into test(c1, c2) values(' || coalesce(rec.c1,'NULL') ||... Regards, Tomasz Myrta
I am having problem there. see what happens sqlstr := 'insert into test(c1, c2) values ('||COALESCE(rec.c1,'NULL')||',' ||'\''||rec.c2||'\')'; WARNING: Error occurred while executing PL/pgSQL function test_fn WARNING: line 8 at assignment ERROR: pg_atoi: error in "NULL": can't parse "NULL" Dont forgot that c1 is int. when i have like this sqlstr := 'insert into test(c1, c2) values ('||COALESCE(rec.c1,NULL)||',' ||'\''||rec.c2||'\')'; NOTICE: <NULL> WARNING: Error occurred while executing PL/pgSQL function test_fn WARNING: line 11 at execute statement ERROR: cannot EXECUTE NULL query That is the problem i am facing. Please shed some light. Thanks Kumar ----- Original Message ----- From: "Tomasz Myrta" <jasiek@klaster.net> To: "Kumar" <sgnerd@yahoo.com.sg> Cc: "psql" <pgsql-sql@postgresql.org> Sent: Thursday, February 12, 2004 6:13 PM Subject: Re: [SQL] How to avoid nulls while writing string for dynamic query > Dnia 2004-02-12 13:31, Użytkownik Kumar napisał: > > The error is because of no value for column c1. If the column c1 is a > > string I might have replace it with empty string. I don't want to > > substitute with '0' which could work. > > > > sqlstr := 'insert into test(c1, c2) values (' ||ISNULL(rec.c1,'0')||',' > > > > ||'\''||rec.c2||'\')'; > > Substitute it with NULL value: > sqlstr := 'insert into test(c1, c2) values(' || coalesce(rec.c1,'NULL') > ||... > > Regards, > Tomasz Myrta
Dear all, I solved it using ISNULL function. sqlstr := 'insert into test(c1, c2) values ('||ISNULL(rec.c1,'NULL')||',' > ||'\''||rec.c2||'\')'; Thanks kumar ----- Original Message ----- From: "Kumar" <sgnerd@yahoo.com.sg> To: "Tomasz Myrta" <jasiek@klaster.net> Cc: "psql" <pgsql-sql@postgresql.org> Sent: Friday, February 13, 2004 10:23 AM Subject: Re: [SQL] How to avoid nulls while writing string for dynamic query > I am having problem there. see what happens > > sqlstr := 'insert into test(c1, c2) values ('||COALESCE(rec.c1,'NULL')||',' > ||'\''||rec.c2||'\')'; > > WARNING: Error occurred while executing PL/pgSQL function test_fn > WARNING: line 8 at assignment > ERROR: pg_atoi: error in "NULL": can't parse "NULL" > > Dont forgot that c1 is int. > > when i have like this > sqlstr := 'insert into test(c1, c2) values ('||COALESCE(rec.c1,NULL)||',' > ||'\''||rec.c2||'\')'; > > NOTICE: <NULL> > WARNING: Error occurred while executing PL/pgSQL function test_fn > WARNING: line 11 at execute statement > ERROR: cannot EXECUTE NULL query > > That is the problem i am facing. Please shed some light. > > Thanks > Kumar > > ----- Original Message ----- > From: "Tomasz Myrta" <jasiek@klaster.net> > To: "Kumar" <sgnerd@yahoo.com.sg> > Cc: "psql" <pgsql-sql@postgresql.org> > Sent: Thursday, February 12, 2004 6:13 PM > Subject: Re: [SQL] How to avoid nulls while writing string for dynamic query > > > > Dnia 2004-02-12 13:31, Użytkownik Kumar napisał: > > > The error is because of no value for column c1. If the column c1 is a > > > string I might have replace it with empty string. I don't want to > > > substitute with '0' which could work. > > > > > > sqlstr := 'insert into test(c1, c2) values (' ||ISNULL(rec.c1,'0')||',' > > > > > > ||'\''||rec.c2||'\')'; > > > > Substitute it with NULL value: > > sqlstr := 'insert into test(c1, c2) values(' || coalesce(rec.c1,'NULL') > > ||... > > > > Regards, > > Tomasz Myrta > > > ---------------------------(end of broadcast)--------------------------- > TIP 7: don't forget to increase your free space map settings
Dnia 2004-02-13 05:53, Użytkownik Kumar napisał: > I am having problem there. see what happens > > sqlstr := 'insert into test(c1, c2) values ('||COALESCE(rec.c1,'NULL')||',' > ||'\''||rec.c2||'\')'; You are preparing a string, so make sure you have strings everywhere: sqlstr := 'insert into test(c1, c2) values ('||COALESCE(rec.c1::text,'NULL')||','||'\''||rec.c2||'\')'; Regards, Tomasz Myrta
oh, ok understood. What will happen for a timestamp field. Let us say c1 is a timestamp column. sqlstr := 'insert into test(c1, c2) values ('||'\''||COALESCE(rec.c1,'NULL')||'\',' > > ||'\''||rec.c2||'\')'; If this case the query will be insert into test(c1,c2) values ('2004-02-13', 'Hai') If there is a null value encountered i will return an error for the following query insert into test(c1,c2) values ('NULL', 'Hai') ERROR: Bad timestamp external representation 'NULL' I think using 'CASE' this could be solved. But instead is there any other simple way to do it. Thanks a lot Mr. Tomasz Myrta Kumar ----- Original Message ----- From: "Tomasz Myrta" <jasiek@klaster.net> To: "Kumar" <sgnerd@yahoo.com.sg> Cc: "psql" <pgsql-sql@postgresql.org> Sent: Friday, February 13, 2004 12:03 PM Subject: Re: [SQL] How to avoid nulls while writing string for dynamic query > Dnia 2004-02-13 05:53, Użytkownik Kumar napisał: > > > I am having problem there. see what happens > > > > sqlstr := 'insert into test(c1, c2) values ('||COALESCE(rec.c1,'NULL')||',' > > ||'\''||rec.c2||'\')'; > > You are preparing a string, so make sure you have strings everywhere: > sqlstr := 'insert into test(c1, c2) values > ('||COALESCE(rec.c1::text,'NULL')||','||'\''||rec.c2||'\')'; > > Regards, > Tomasz Myrta
Dnia 2004-02-13 08:13, Użytkownik Kumar napisał: > oh, ok understood. > What will happen for a timestamp field. Let us say c1 is a timestamp column. > > sqlstr := 'insert into test(c1, c2) values > ('||'\''||COALESCE(rec.c1,'NULL')||'\',' > >>> ||'\''||rec.c2||'\')'; > > > If this case the query will be > insert into test(c1,c2) values ('2004-02-13', 'Hai') > > If there is a null value encountered i will return an error for the > following query > insert into test(c1,c2) values ('NULL', 'Hai') > ERROR: Bad timestamp external representation 'NULL' It's because you can't use quotes with null. Valid query is: insert into test(c1,c2) values (NULL, 'Hai'); Your dynamic query will then look like: sqlstr := 'insert into test(c1, c2) values (' ||COALESCE('\'' || rec.c1 || '\'','NULL') ... or more elegant: sqlstr := 'insert into test(c1, c2) values (' ||COALESCE(quote_literal(rec.c1),'NULL') ... Regards, Tomasz Myrta
Thanks Tomasz Myrta. It is wonderful. I am still amazed from where you guys knowing the options like quote_literal, etc. Kumar ----- Original Message ----- From: "Tomasz Myrta" <jasiek@klaster.net> To: "Kumar" <sgnerd@yahoo.com.sg> Cc: "psql" <pgsql-sql@postgresql.org> Sent: Friday, February 13, 2004 1:37 PM Subject: Re: [SQL] How to avoid nulls while writing string for dynamic query > Dnia 2004-02-13 08:13, Użytkownik Kumar napisał: > > oh, ok understood. > > What will happen for a timestamp field. Let us say c1 is a timestamp column. > > > > sqlstr := 'insert into test(c1, c2) values > > ('||'\''||COALESCE(rec.c1,'NULL')||'\',' > > > >>> ||'\''||rec.c2||'\')'; > > > > > > If this case the query will be > > insert into test(c1,c2) values ('2004-02-13', 'Hai') > > > > If there is a null value encountered i will return an error for the > > following query > > insert into test(c1,c2) values ('NULL', 'Hai') > > ERROR: Bad timestamp external representation 'NULL' > It's because you can't use quotes with null. Valid query is: > insert into test(c1,c2) values (NULL, 'Hai'); > > Your dynamic query will then look like: > > sqlstr := 'insert into test(c1, c2) values (' ||COALESCE('\'' || rec.c1 > || '\'','NULL') ... > > or more elegant: > > sqlstr := 'insert into test(c1, c2) values (' > ||COALESCE(quote_literal(rec.c1),'NULL') ... > > Regards, > Tomasz Myrta
Dnia 2004-02-13 10:14, Użytkownik Kumar napisał: > Thanks Tomasz Myrta. It is wonderful. I am still amazed from where you guys > knowing the options like quote_literal, etc. > > Kumar Just read the manual ;-) 6.4. String Functions and Operators Tomasz