[SQL] 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 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
Re: [SQL] executing dynamic commands
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;
<[EMAIL PROTECTED]> wrote in message
news:[EMAIL PROTECTED]
> 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 archiv
[SQL] CREATE INDEX with order clause
Hi, I would like to create an index on a table, specifying an order clause for one of the columns. CREATE INDEX IDX_GSLOG_EVENT_PLAYER_EVENT_TIME_DESC ON GSLOG_EVENT(PLAYER_USERNAME, EVENT_NAME, EVENT_DATE_CREATED DESC); which is not a valid, as the order clause DESC is not supported. Such as index would improve performance of query like: SELECT GAME_CLIENT_VERSION FROM GSLOG_EVENT WHERE PLAYER_USERNAME = ? AND EVENT_NAME = ? AND EVENT_DATE_CREATED < ? ORDER BY EVENT_DATE_CREATED DESC LIMIT 1 Actually, I’m not sure that is useful; perhaps PostgreSQL handles pretty well such query using an index such as: CREATE INDEX IDX_GSLOG_EVENT_PLAYER_EVENT_TIME_DESC ON GSLOG_EVENT(PLAYER_USERNAME, EVENT_NAME, EVENT_DATE_CREATED); Any idea? -- Daniel CAUNE Ubisoft Online Technology (514) 4090 2040 ext. 5418
Re: [SQL] CREATE INDEX with order clause
"Daniel Caune" <[EMAIL PROTECTED]> writes: > I would like to create an index on a table, specifying an order clause > for one of the columns. Search the archives for discussions of reverse-sort operator classes (you might also get hits on the shorthand "opclass"). regards, tom lane ---(end of broadcast)--- TIP 6: explain analyze is your friend
Re: [SQL] executing dynamic commands
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 make it a bit more clear: I want to copy
all records from table1 to table2 assuming that the two tables have exactly the
same column 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 row per 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;
>
>
>
>
><[EMAIL PROTECTED]> wrote in message
>news:[EMAIL PROTECTED]
>> 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 arr
Re: [SQL] executing dynamic commands
On Wed, 1 Feb 2006 [EMAIL PROTECTED] 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 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) You might have better luck with a INSERT ... SELECT where you've reordered the columns in the select list INSERT INTO tabledest SELECT FROM tablesrc ---(end of broadcast)--- TIP 2: Don't 'kill -9' the postmaster
[SQL] Does PostgreSQL support job?
Hi, I try to find in the documentation whether PostgreSQL supports job, but I miserably failed. Does PostgreSQL support job? If not, what is the mechanism mostly adopted by PostgreSQL administrators for running jobs against PostgreSQL? I was thinking about using cron/plsql/sql-scripts on Linux. Thanks (Tom Lane J) -- Daniel CAUNE
Re: [SQL] Does PostgreSQL support job?
Daniel Caune wrote: > Hi, > > > > I try to find in the documentation whether PostgreSQL supports job, but > I miserably failed. Does PostgreSQL support job? If not, what is the > mechanism mostly adopted by PostgreSQL administrators for running jobs > against PostgreSQL? I was thinking about using cron/plsql/sql-scripts > on Linux. The unix cron systems is what most people use. -- Bruce Momjian| http://candle.pha.pa.us [email protected] | (610) 359-1001 + If your life is a hard drive, | 13 Roberts Road + Christ can be your backup.| Newtown Square, Pennsylvania 19073 ---(end of broadcast)--- TIP 5: don't forget to increase your free space map settings
Re: [SQL] Does PostgreSQL support job?
Daniel Caune wrote: > Hi, > > I try to find in the documentation whether PostgreSQL supports job, > but I miserably failed. Does PostgreSQL support job? If not, what > is the mechanism mostly adopted by PostgreSQL administrators for > running jobs against PostgreSQL? I was thinking about using > cron/plsql/sql-scripts on Linux. The answer really depends on what you mean by "jobs". If you have a database task that can be expressed as a series of commands with no interaction involved, you can just put those commands in a file (your-job-name.sql) and run it using psql and cron: # replace leading stars with cron time settings * * * * * psql your-database -i your-job-name.sql If you need something more complex, either a function which is executed from a script or a full-blown client program may be required. IME that's fairly rare. -Owen ---(end of broadcast)--- TIP 2: Don't 'kill -9' the postmaster
Re: [SQL] Does PostgreSQL support job?
> -Message d'origine- > De : [EMAIL PROTECTED] [mailto:pgsql-sql- > [EMAIL PROTECTED] De la part de Bruce Momjian > Envoyé : mercredi, février 01, 2006 17:57 > À : Daniel Caune > Cc : [email protected] > Objet : Re: [SQL] Does PostgreSQL support job? > > Daniel Caune wrote: > > Hi, > > > > > > > > I try to find in the documentation whether PostgreSQL supports job, but > > I miserably failed. Does PostgreSQL support job? If not, what is the > > mechanism mostly adopted by PostgreSQL administrators for running jobs > > against PostgreSQL? I was thinking about using cron/plsql/sql-scripts > > on Linux. > > The unix cron systems is what most people use. > OK. Thanks. That's fine! ---(end of broadcast)--- TIP 1: if posting/reading through Usenet, please send an appropriate subscribe-nomail command to [EMAIL PROTECTED] so that your message can get through to the mailing list cleanly
Re: [SQL] Does PostgreSQL support job?
On Wed, Feb 01, 2006 at 05:53:52PM -0500, Daniel Caune wrote: > I try to find in the documentation whether PostgreSQL supports job, but > I miserably failed. Does PostgreSQL support job? If not, what is the I don't know what "job" is, but it sounds like you want "cron" (since you mention it). Yes, use that. A -- Andrew Sullivan | [EMAIL PROTECTED] The plural of anecdote is not data. --Roger Brinner ---(end of broadcast)--- TIP 5: don't forget to increase your free space map settings
Re: [SQL] Does PostgreSQL support job?
> -Message d'origine- > De : Owen Jacobson [mailto:[EMAIL PROTECTED] > Envoyé : mercredi, février 01, 2006 18:00 > À : Daniel Caune; [email protected] > Objet : RE: [SQL] Does PostgreSQL support job? > > Daniel Caune wrote: > > Hi, > > > > I try to find in the documentation whether PostgreSQL supports job, > > but I miserably failed. Does PostgreSQL support job? If not, what > > is the mechanism mostly adopted by PostgreSQL administrators for > > running jobs against PostgreSQL? I was thinking about using > > cron/plsql/sql-scripts on Linux. > > The answer really depends on what you mean by "jobs". If you have a > database task that can be expressed as a series of commands with no > interaction involved, you can just put those commands in a file (your-job- > name.sql) and run it using psql and cron: > > # replace leading stars with cron time settings > * * * * * psql your-database -i your-job-name.sql > Yes, that's it. A job is a task, i.e. set of statements, which is scheduled to run against a RDBMS at periodical times. Some RDBMS, such as SQL Server and Oracle, support that feature, even if such a feature is managed differently from a RDBMS to another. OK. I get it. I will use cron and psql as I was planning to do so. > If you need something more complex, either a function which is executed > from a script or a full-blown client program may be required. IME that's > fairly rare. > I'm not sure to understand. Why calling a function from a script is different from executing a series of SQL commands? I mean, I can run a script defined as follows: SELECT myjob(); where myjob is a stored procedure such as: CREATE OR REPLACE FUNCTION myjob() RETURNS void AS $$ END; $$ LANGUAGE PLPGSQL; Does that make sense? -- Daniel CAUNE ---(end of broadcast)--- TIP 1: if posting/reading through Usenet, please send an appropriate subscribe-nomail command to [EMAIL PROTECTED] so that your message can get through to the mailing list cleanly
Re: [SQL] Does PostgreSQL support job?
Daniel Caune wrote: > Yes, that's it. A job is a task, i.e. set of statements, which is > scheduled to run against a RDBMS at periodical times. Some RDBMS, > such as SQL Server ..., the current alpha MySQL, ... > and Oracle, support that feature, even if such a > feature is managed differently from a RDBMS to another. I was amused when I read the MySQL news in LWN.net, because most comments were things like "what the hell has this half-baked feature has to do in a RDBMS anyway". http://lwn.net/Articles/167895/ -- Alvaro Herrerahttp://www.CommandPrompt.com/ PostgreSQL Replication, Consulting, Custom Development, 24x7 support ---(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
Re: [SQL] Does PostgreSQL support job?
> -Message d'origine- > De : [EMAIL PROTECTED] [mailto:pgsql-sql- > [EMAIL PROTECTED] De la part de Alvaro Herrera > Envoyé : mercredi 1 février 2006 19:28 > À : Daniel Caune > Cc : Owen Jacobson; [email protected] > Objet : Re: [SQL] Does PostgreSQL support job? > > Daniel Caune wrote: > > > Yes, that's it. A job is a task, i.e. set of statements, which is > > scheduled to run against a RDBMS at periodical times. Some RDBMS, > > such as SQL Server > > ..., the current alpha MySQL, ... > > > and Oracle, support that feature, even if such a > > feature is managed differently from a RDBMS to another. > > > I was amused when I read the MySQL news in LWN.net, because most > comments were things like "what the hell has this half-baked feature has > to do in a RDBMS anyway". > > http://lwn.net/Articles/167895/ > It's true that implementing a job management within an RDBMS is somewhat reinventing the wheel, especially on UNIX systems where cron exists (even on Windows, which supports scheduled tasks). Anyway, job support within a RDBMS sounds more like a facility. "While I have built a number of large and small applications with various time-based event scheduling tables stored in an SQL database, including things like triggers that send asynchronous notifications to daemon clients to advise them to re-query for updated schedules, it never in my wildest imaginings occured to me to actually initiate execution autonomously from the database back end." [zblaxell, 2006-01-25, http://lwn.net/Articles/167895/] Well, perhaps zblaxell has only worked on operational systems (OLTP), but such autonomy is sometimes useful in low-cost business intelligence systems (OLAP). -- Daniel CAUNE ---(end of broadcast)--- TIP 4: Have you searched our list archives? http://archives.postgresql.org
[SQL] Function Dependency
Hello, I am maintaining an application that has over 400 procedures and functions written in plsql, and around 100 tables. I want to generate a function dependency chart to depict the following: 1. Inter function/procedure dependencies 2. function-tables dependencies 3. function-sequences depencies Is there a standard method of doing this? Thanks in advance, Padam. begin:vcard fn:Padam Singh n:Singh;Padam org:Inventum Technologies Pvt. Ltd.;Engineering adr:SDA Commercial Complex;;C-17;New Delhi;Delhi;110016;India email;internet:[EMAIL PROTECTED] title:Sr. Solutions Architect tel;work:+91-11-55650222 tel;fax:+91-11-26518800 tel;cell:+91-9810146640 x-mozilla-html:TRUE url:http://www.inventum.cc version:2.1 end:vcard ---(end of broadcast)--- TIP 3: Have you checked our extensive FAQ? http://www.postgresql.org/docs/faq
