Re: Queyring for columns which are exist in table.
От | Sim Zacks |
---|---|
Тема | Re: Queyring for columns which are exist in table. |
Дата | |
Msg-id | 4D414F41.1020804@compulab.co.il обсуждение исходный текст |
Ответ на | Queyring for columns which are exist in table. ("Santosh Bhujbal (sabhujba)" <sabhujba@cisco.com>) |
Список | pgsql-general |
On 01/27/2011 09:52 AM, Santosh Bhujbal (sabhujba) wrote:
the name datatype won't cast it into a selectable column. CREATE OR REPLACE FUNCTION ColumnAlreadyExists(name, name) RETURNS INTEGER AS E'DECLARE columnCount INTEGER;
BEGIN
SELECT COUNT (pg_attribute.attname) into columnCount FROM pg_attribute,pg_class, pg_type WHERE ((pg_attribute.attrelid=pg_class.oid) AND (pg_attribute.atttypid=pg_type.oid) AND (pg_class.relname = $1) AND (pg_attribute.attname = $2));
IF columnCount = 0 THEN
RETURN 0;
END IF;
RETURN 1;
END;
' LANGUAGE 'plpgsql';
DROP FUNCTION checkColumn(name,name,name);
CREATE OR REPLACE FUNCTION checkColumn(name, name, name) RETURNS name AS E'
DECLARE isColumnExist INTEGER;
BEGIN
SELECT ColumnAlreadyExists ($1,$2) into isColumnExist;
IF isColumnExist = 0 THEN
RETURN name($3);
ELSE
RETURN name($2);
END IF;
END;
' LANGUAGE 'plpgsql';
Function checkColumn should return proper column name (second parameter) if column exist and third parameter if column not exist.
NOW when I try to execute following command it returns improper result.
I expect proper column values as a output of query.
SELECT(checkColumn('tbl','c2','0'))::name FROM tbl;
mydb=# SELECT (checkColumn('tbl','c2','0'))::name FROM tbl;
checkcolumn
-------------
c2
c2
c2
c2
c2
c2
c2
c2
(8 rows)
mydb=#
Above query should return actual values present for c2 column in tbl.
But it’s not working as desired.
Please help me in this.
Thanks in advance,
Santosh.
Forgetting about your function, if you try select 'c2'::name from tbl it will also return c2 as a name datatype.
What you want to do is a dynamic query where you use execute or for row in execute in a plpgsql function.
Also to see if the column exists, I would recommend using information_schema.columns
В списке pgsql-general по дате отправления: