Обсуждение: executing dynamic commands
Hi,
I user PostgreSQl 8.0.4 on Win2003 Server and write a function to copy rows from one table into another table with the
samecolumn definition.
My first approach was to use something like:
query_value := 'INSERT INTO ' || tabledest || ' SELECT * FROM ' || tablesrc;
EXECUTE query_value;
This only works if the column definition AND the order between source and destination is the same !
In my case I have always the same column definitions but they are not in the same order between source and destination
table.
What I tryed then is to loop through the column definition of the source and query the sourcetable for the value. For
thatI have to execut a query with dynamic tablename and dynamic columname to generate two stings one with the
columndefinitinand one with the columnvalues to exececute something like: INSERT INTO tabelfoo (columndefinitinstring)
VALUES(columnvaluesstring)
see snip of function:
fieldvalues RECORD;
output RECORD;
insertvalues VARCHAR;
fieldname VARCHAR;
-- Get Attribute List from Table and write it to output
-- Read Values of Fieldname from source
query_value := 'select * from ' || tablesrc ;
FOR fieldvalues IN EXECUTE query_value LOOP
FOR output IN SELECT a.attnum, a.attname AS field, FROM pg_class c, pg_attribute a, pg_type t WHERE
c.relname = tablesrc AND a.attnum > 0 AND a.attrelid = c.oid AND a.atttypid = t.oid ORDER BY
a.attnumLOOP -- Read Field Name from Out Table fieldname := output.field; -- Write Field Name into
Variable IF insertcolumns IS NULL THEN insertcolumns := fieldname; ELSE insertcolumns := insertcolumns
||',' || fieldname; END IF;
Until here everyting is fine ... but now I try to query the value from RECORD fieldvalues with the columname fieldname
variablefrom the inner loop !
I tryed the following ...
query_value := 'select quote_ident(' || fieldvalues || ').quote_literal(' || fieldname ||')';
EXECUTE query_value;
and I get the following error message ...
ERROR: could not find array type for data type record
CONTEXT: SQL statement "SELECT 'select quote_ident(' || $1 || ').quote_literal(' || $2 ||')'"
PL/pgSQL function "prx_db__appendtable" line 87 at assignment
END LOOP; END LOOP;
I know the function is not runnable, but my question is how can I dynamically combine "fieldvalues"."fieldname" to
readthe values column by colum out if a RECORD variable to generate the "columnvaluesstring" mentioned above ?!
Maybe this approach is to complicated and there is a quick and easy solution ?!
Any help is very much appreciated !!
Thanx a lot & Regards
Chris
Talk about obfuscated.... Are you trying to retrieve the table structure /
schema from the PG System Catalogs ?
If so -- you are better off using a VIEW instead of a manual procedure
because it will automatically kepp up with the current schema definition...
Try this:
-- DROP VIEW sys_table_schemas;
CREATE OR REPLACE VIEW sys_table_schemas ASSELECT pc.oid AS tbl_oid, pc.relname::character varying AS table_name,
pa.attname::character varying AS column_name, pt.typname AS data_type, CASE WHEN
substr(pt.typname::text,1, 3)::name = 'int'::name THEN
'integer'::name WHEN pt.typname = 'bool'::name THEN 'boolean'::name ELSE pt.typname END AS
udt_name,pa.attnum AS ordinal_position, 254 AS str_length, CASE WHEN pa.attnotnull THEN false
ELSEtrue END AS nulls_allowed, CASE WHEN substr(pa.attname::text, 1, 3) = 'lu_'::text THEN true
ELSE false END AS lookup, CASE WHEN pd.description::character varying IS NOT NULL THEN
pd.description::character varying WHEN pa.attname IS NOT NULL THEN pa.attname::character varying
ELSENULL::character varying END AS label FROM ONLY pg_class pc JOIN ONLY pg_attribute pa ON pc.oid =
pa.attrelidAND pc.relnamespace =
2200::oid AND pc.reltype > 0::oid AND (pc.relkind = 'r'::"char" OR
pc.relkind = 'v'::"char") JOIN ONLY pg_type pt ON pa.atttypid = pt.oid LEFT JOIN ONLY pg_description pd ON pc.oid =
pd.objoidAND pa.attnum =
pd.objsubid WHERE pa.attnum > 0 ORDER BY pc.relname::character varying, pa.attnum;
ALTER TABLE sys_table_schemas OWNER TO "public";
SELECT * FROM sys_table_schemas;
<christian.michels@eifelgeist.com> wrote in message
news:15802822.125111138807576371.JavaMail.servlet@kundenserver...
> Hi,
>
> I user PostgreSQl 8.0.4 on Win2003 Server and write a function to copy
> rows from one table into another table with the same column definition.
> My first approach was to use something like:
>
> query_value := 'INSERT INTO ' || tabledest || ' SELECT * FROM ' ||
> tablesrc;
> EXECUTE query_value;
>
> This only works if the column definition AND the order between source and
> destination is the same !
> In my case I have always the same column definitions but they are not in
> the same order between source and destination table.
> What I tryed then is to loop through the column definition of the source
> and query the sourcetable for the value. For that I have to execut a query
> with dynamic tablename and dynamic columname to generate two stings one
> with the columndefinitin and one with the columnvalues to exececute
> something like: INSERT INTO tabelfoo (columndefinitinstring) VALUES
> (columnvaluesstring)
>
> see snip of function:
>
> fieldvalues RECORD;
> output RECORD;
> insertvalues VARCHAR;
> fieldname VARCHAR;
>
>
> -- Get Attribute List from Table and write it to output
> -- Read Values of Fieldname from source
> query_value := 'select * from ' || tablesrc ;
>
> FOR fieldvalues IN EXECUTE query_value LOOP
>
> FOR output IN SELECT a.attnum,
> a.attname AS field,
> FROM
> pg_class c, pg_attribute a, pg_type t
> WHERE
> c.relname = tablesrc AND
> a.attnum > 0 AND
> a.attrelid = c.oid AND
> a.atttypid = t.oid
> ORDER BY a.attnum LOOP
>
> -- Read Field Name from Out Table
> fieldname := output.field;
>
> -- Write Field Name into Variable
> IF insertcolumns IS NULL THEN
> insertcolumns := fieldname;
> ELSE
> insertcolumns := insertcolumns || ',' || fieldname;
> END IF;
>
> Until here everyting is fine ... but now I try to query the value from
> RECORD fieldvalues with the columname fieldname variable from the inner
> loop !
> I tryed the following ...
>
> query_value := 'select quote_ident(' || fieldvalues || ').quote_literal('
> || fieldname ||')';
>
> EXECUTE query_value;
>
>
> and I get the following error message ...
>
> ERROR: could not find array type for data type record
> CONTEXT: SQL statement "SELECT 'select quote_ident(' || $1 ||
> ').quote_literal(' || $2 ||')'"
> PL/pgSQL function "prx_db__appendtable" line 87 at assignment
>
>
> END LOOP;
>
> END LOOP;
>
> I know the function is not runnable, but my question is how can I
> dynamically combine "fieldvalues"."fieldname" to read the values column by
> colum out if a RECORD variable to generate the "columnvaluesstring"
> mentioned above ?!
> Maybe this approach is to complicated and there is a quick and easy
> solution ?!
>
> Any help is very much appreciated !!
>
> Thanx a lot & Regards
>
> Chris
>
> ---------------------------(end of broadcast)---------------------------
> TIP 9: In versions below 8.0, the planner will ignore your desire to
> choose an index scan if your joining column's datatypes do not
> match
>
Thanx for the quick response !
Sorry for asking a bit confusing question ... Using the View is a good idea but does not fully solve my problem. To
makeit a bit more clear: I want to copy all records from table1 to table2 assuming that the two tables have exactly the
samecolumn definition and column order. I could do that executing INSERT INTO tablefoo1 SELECT * FROM tablefoo2;
But how can I do the copying if the column order is different between tablefoo1 and tablefoo2 ?
My approach was to dynamically assemble a string1 with all fieldnames and a string2 with the corresponding field values
rowper row using a plpgsql function. The result would be a row per row copying using INSERT INTO tablefoo1 (string1)
VALUES(string2). My problem is that I not manage to read the fieldvalues row by row.
Do you have any idea ?
Thanx a lot !
Regards
Chris
>
>Talk about obfuscated.... Are you trying to retrieve the table structure /
>schema from the PG System Catalogs ?
>
>If so -- you are better off using a VIEW instead of a manual procedure
>because it will automatically kepp up with the current schema definition...
>
>Try this:
>
>-- DROP VIEW sys_table_schemas;
>
>CREATE OR REPLACE VIEW sys_table_schemas AS
> SELECT pc.oid AS tbl_oid, pc.relname::character varying AS table_name,
>pa.attname::character varying AS column_name, pt.typname AS data_type,
> CASE
> WHEN substr(pt.typname::text, 1, 3)::name = 'int'::name THEN
>'integer'::name
> WHEN pt.typname = 'bool'::name THEN 'boolean'::name
> ELSE pt.typname
> END AS udt_name, pa.attnum AS ordinal_position, 254 AS str_length,
> CASE
> WHEN pa.attnotnull THEN false
> ELSE true
> END AS nulls_allowed,
> CASE
> WHEN substr(pa.attname::text, 1, 3) = 'lu_'::text THEN true
> ELSE false
> END AS lookup,
> CASE
> WHEN pd.description::character varying IS NOT NULL THEN
>pd.description::character varying
> WHEN pa.attname IS NOT NULL THEN pa.attname::character varying
> ELSE NULL::character varying
> END AS label
> FROM ONLY pg_class pc
> JOIN ONLY pg_attribute pa ON pc.oid = pa.attrelid AND pc.relnamespace =
>2200::oid AND pc.reltype > 0::oid AND (pc.relkind = 'r'::"char" OR
>pc.relkind = 'v'::"char")
> JOIN ONLY pg_type pt ON pa.atttypid = pt.oid
> LEFT JOIN ONLY pg_description pd ON pc.oid = pd.objoid AND pa.attnum =
>pd.objsubid
> WHERE pa.attnum > 0
> ORDER BY pc.relname::character varying, pa.attnum;
>
>ALTER TABLE sys_table_schemas OWNER TO "public";
>
>SELECT * FROM sys_table_schemas;
>
>
>
>
><christian.michels@eifelgeist.com> wrote in message
>news:15802822.125111138807576371.JavaMail.servlet@kundenserver...
>> Hi,
>>
>> I user PostgreSQl 8.0.4 on Win2003 Server and write a function to copy
>> rows from one table into another table with the same column definition.
>> My first approach was to use something like:
>>
>> query_value := 'INSERT INTO ' || tabledest || ' SELECT * FROM ' ||
>> tablesrc;
>> EXECUTE query_value;
>>
>> This only works if the column definition AND the order between source and
>> destination is the same !
>> In my case I have always the same column definitions but they are not in
>> the same order between source and destination table.
>> What I tryed then is to loop through the column definition of the source
>> and query the sourcetable for the value. For that I have to execut a query
>> with dynamic tablename and dynamic columname to generate two stings one
>> with the columndefinitin and one with the columnvalues to exececute
>> something like: INSERT INTO tabelfoo (columndefinitinstring) VALUES
>> (columnvaluesstring)
>>
>> see snip of function:
>>
>> fieldvalues RECORD;
>> output RECORD;
>> insertvalues VARCHAR;
>> fieldname VARCHAR;
>>
>>
>> -- Get Attribute List from Table and write it to output
>> -- Read Values of Fieldname from source
>> query_value := 'select * from ' || tablesrc ;
>>
>> FOR fieldvalues IN EXECUTE query_value LOOP
>>
>> FOR output IN SELECT a.attnum,
>> a.attname AS field,
>> FROM
>> pg_class c, pg_attribute a, pg_type t
>> WHERE
>> c.relname = tablesrc AND
>> a.attnum > 0 AND
>> a.attrelid = c.oid AND
>> a.atttypid = t.oid
>> ORDER BY a.attnum LOOP
>>
>> -- Read Field Name from Out Table
>> fieldname := output.field;
>>
>> -- Write Field Name into Variable
>> IF insertcolumns IS NULL THEN
>> insertcolumns := fieldname;
>> ELSE
>> insertcolumns := insertcolumns || ',' || fieldname;
>> END IF;
>>
>> Until here everyting is fine ... but now I try to query the value from
>> RECORD fieldvalues with the columname fieldname variable from the inner
>> loop !
>> I tryed the following ...
>>
>> query_value := 'select quote_ident(' || fieldvalues || ').quote_literal('
>> || fieldname ||')';
>>
>> EXECUTE query_value;
>>
>>
>> and I get the following error message ...
>>
>> ERROR: could not find array type for data type record
>> CONTEXT: SQL statement "SELECT 'select quote_ident(' || $1 ||
>> ').quote_literal(' || $2 ||')'"
>> PL/pgSQL function "prx_db__appendtable" line 87 at assignment
>>
>>
>> END LOOP;
>>
>> END LOOP;
>>
>> I know the function is not runnable, but my question is how can I
>> dynamically combine "fieldvalues"."fieldname" to read the values column by
>> colum out if a RECORD variable to generate the "columnvaluesstring"
>> mentioned above ?!
>> Maybe this approach is to complicated and there is a quick and easy
>> solution ?!
>>
>> Any help is very much appreciated !!
>>
>> Thanx a lot & Regards
>>
>> Chris
>>
>> ---------------------------(end of broadcast)---------------------------
>> TIP 9: In versions below 8.0, the planner will ignore your desire to
>> choose an index scan if your joining column's datatypes do not
>> match
>>
>
>
>
>---------------------------(end of broadcast)---------------------------
>TIP 4: Have you searched our list archives?
>
> http://archives.postgresql.org
On Wed, 1 Feb 2006 christian.michels@eifelgeist.com wrote: > Hi, > > I user PostgreSQl 8.0.4 on Win2003 Server and write a function to copy rows from one table into another table with thesame column definition. > My first approach was to use something like: > > query_value := 'INSERT INTO ' || tabledest || ' SELECT * FROM ' || tablesrc; > EXECUTE query_value; > > This only works if the column definition AND the order between source and destination is the same ! > In my case I have always the same column definitions but they are not in> the same order between source and destinationtable. > What I tryed then is to loop through the column definition of the source > and query the sourcetable for the value. For that I have to execut a > query with dynamic tablename and dynamic columname to generate two > stings one with the columndefinitin and one with the columnvalues to > exececute something like: INSERT INTO tabelfoo (columndefinitinstring) > VALUES (columnvaluesstring) You might have better luck with a INSERT ... SELECT where you've reordered the columns in the select list INSERT INTO tabledest SELECT <reordered columns to match dest order> FROM tablesrc
Thanx a lot guys - it works ! Cheers Chris On Wed, 1 Feb 2006 christian ( dot ) michels ( at ) eifelgeist ( dot ) com wrote: > Hi, > > I user PostgreSQl 8.0.4 on Win2003 Server and write a function to copy rows from one table into another table with thesame column definition. > My first approach was to use something like: > > query_value := 'INSERT INTO ' || tabledest || ' SELECT * FROM ' || tablesrc; > EXECUTE query_value; > > This only works if the column definition AND the order between source and destination is the same ! > In my case I have always the same column definitions but they are not in> the same order between source and destinationtable. > What I tryed then is to loop through the column definition of the source > and query the sourcetable for the value. For that I have to execut a > query with dynamic tablename and dynamic columname to generate two > stings one with the columndefinitin and one with the columnvalues to > exececute something like: INSERT INTO tabelfoo (columndefinitinstring) > VALUES (columnvaluesstring) You might have better luck with a INSERT ... SELECT where you've reordered the columns in the select list INSERT INTO tabledest SELECT <reordered columns to match dest order> FROM tablesrc
In your function why not create a temporary table then use that for your
processing ?
CREATE TEMPRORARY TABLE tabledest AS (SELECT * FROM tblsrc WHERE condition);
<christian.michels@eifelgeist.com> wrote in message
news:15802822.125111138807576371.JavaMail.servlet@kundenserver...
> Hi,
>
> I user PostgreSQl 8.0.4 on Win2003 Server and write a function to copy
> rows from one table into another table with the same column definition.
> My first approach was to use something like:
>
> query_value := 'INSERT INTO ' || tabledest || ' SELECT * FROM ' ||
> tablesrc;
> EXECUTE query_value;
>
> This only works if the column definition AND the order between source and
> destination is the same !
> In my case I have always the same column definitions but they are not in
> the same order between source and destination table.
> What I tryed then is to loop through the column definition of the source
> and query the sourcetable for the value. For that I have to execut a query
> with dynamic tablename and dynamic columname to generate two stings one
> with the columndefinitin and one with the columnvalues to exececute
> something like: INSERT INTO tabelfoo (columndefinitinstring) VALUES
> (columnvaluesstring)
>
> see snip of function:
>
> fieldvalues RECORD;
> output RECORD;
> insertvalues VARCHAR;
> fieldname VARCHAR;
>
>
> -- Get Attribute List from Table and write it to output
> -- Read Values of Fieldname from source
> query_value := 'select * from ' || tablesrc ;
>
> FOR fieldvalues IN EXECUTE query_value LOOP
>
> FOR output IN SELECT a.attnum,
> a.attname AS field,
> FROM
> pg_class c, pg_attribute a, pg_type t
> WHERE
> c.relname = tablesrc AND
> a.attnum > 0 AND
> a.attrelid = c.oid AND
> a.atttypid = t.oid
> ORDER BY a.attnum LOOP
>
> -- Read Field Name from Out Table
> fieldname := output.field;
>
> -- Write Field Name into Variable
> IF insertcolumns IS NULL THEN
> insertcolumns := fieldname;
> ELSE
> insertcolumns := insertcolumns || ',' || fieldname;
> END IF;
>
> Until here everyting is fine ... but now I try to query the value from
> RECORD fieldvalues with the columname fieldname variable from the inner
> loop !
> I tryed the following ...
>
> query_value := 'select quote_ident(' || fieldvalues || ').quote_literal('
> || fieldname ||')';
>
> EXECUTE query_value;
>
>
> and I get the following error message ...
>
> ERROR: could not find array type for data type record
> CONTEXT: SQL statement "SELECT 'select quote_ident(' || $1 ||
> ').quote_literal(' || $2 ||')'"
> PL/pgSQL function "prx_db__appendtable" line 87 at assignment
>
>
> END LOOP;
>
> END LOOP;
>
> I know the function is not runnable, but my question is how can I
> dynamically combine "fieldvalues"."fieldname" to read the values column by
> colum out if a RECORD variable to generate the "columnvaluesstring"
> mentioned above ?!
> Maybe this approach is to complicated and there is a quick and easy
> solution ?!
>
> Any help is very much appreciated !!
>
> Thanx a lot & Regards
>
> Chris
>
> ---------------------------(end of broadcast)---------------------------
> TIP 9: In versions below 8.0, the planner will ignore your desire to
> choose an index scan if your joining column's datatypes do not
> match
>