Thread: Executing plpgsql scripts using psql, is that possible?

Executing plpgsql scripts using psql, is that possible?

From
Daniel CAUNE
Date:
Hi,

I would like to write some administration plpgsql scripts that populate some tables (dimension tables) and to execute
themusing psql.  I’m not sure that is possible with psql as it is with Oracle sqlplus or SQL Server MSQuery: 

Oracle sqlplus:
---------------
DECLARE V_MyObjectID bigint;
BEGIN V_MyObjectID := RegisterMyObject('a string', 'another string'); AddObjectProperty(V_MyObjectID, 'a string');
AddObjectProperty(V_MyObjectID,'another string'); 
END;

SQL Server MSQuery:
-------------------
DECLARE @MyObjectID int
SET @MyObjectID = RegisterMyObject('a string', 'another string')
EXECUTE AddObjectProperty(MyObjectID, 'a string');
EXECUTE AddObjectProperty(MyObjectID, 'another string');

Any idea how I can translate such a script for psql?  I mean, without creating a function that wraps the whole, of
course!:-) 

Thanks,


Daniel



Re: Executing plpgsql scripts using psql, is that possible?

From
John DeSoi
Date:
On Jan 16, 2006, at 5:35 AM, Daniel CAUNE wrote:

> I would like to write some administration plpgsql scripts that
> populate some tables (dimension tables) and to execute them using
> psql.  I’m not sure that is possible with psql as it is with Oracle
> sqlplus or SQL Server MSQuery:


If you want to execute a plpgsql function from a file using psql,
just call it with SELECT. So your file might have:

create or replace function my_function(params integer)
returns integer as $$
DECLARE  V_MyObjectID bigint;
BEGIN  V_MyObjectID := RegisterMyObject('a string', 'another string');  AddObjectProperty(V_MyObjectID, 'a string');
AddObjectProperty(V_MyObjectID,'another string'); 
....
END;
$$ language plpgsql;


SELECT my_function(1);


and then psql -f script.sql my_db



John DeSoi, Ph.D.
http://pgedit.com/
Power Tools for PostgreSQL



Re: Executing plpgsql scripts using psql, is that possible?

From
Daniel CAUNE
Date:

> -----Message d'origine-----
> De : pgsql-sql-owner@postgresql.org [mailto:pgsql-sql-
> owner@postgresql.org] De la part de John DeSoi
> Envoyé : lundi 16 janvier 2006 08:51
> À : Daniel CAUNE
> Cc : pgsql-sql@postgresql.org
> Objet : Re: [SQL] Executing plpgsql scripts using psql, is that possible?
>
>
> On Jan 16, 2006, at 5:35 AM, Daniel CAUNE wrote:
>
> > I would like to write some administration plpgsql scripts that
> > populate some tables (dimension tables) and to execute them using
> > psql.  I’m not sure that is possible with psql as it is with Oracle
> > sqlplus or SQL Server MSQuery:
>
>
> If you want to execute a plpgsql function from a file using psql,
> just call it with SELECT. So your file might have:
>
> create or replace function my_function(params integer)
> returns integer as $$
> DECLARE
>    V_MyObjectID bigint;
> BEGIN
>    V_MyObjectID := RegisterMyObject('a string', 'another string');
>    AddObjectProperty(V_MyObjectID, 'a string');
>    AddObjectProperty(V_MyObjectID, 'another string');
> ....
> END;
> $$ language plpgsql;
>
>
> SELECT my_function(1);
>
>
> and then psql -f script.sql my_db
>

Yes, but that requires creating a function while I would prefer not having do so, as I said in my previous mail: "I
mean,without creating a function that wraps the whole, of course! :-)".  Why?  Actually this is not a function; this is
ascript that inserts static data into dimension tables such as Country, Language, etc. 

I have several scripts responsible for creating the database and all the objects (tables, views, constraints, indexes,
user-definedfunctions, etc.) of my project.  I would like to have some other scripts to initialize dimension tables,
i.e.inserting static data in those tables.  The idea is to automate the whole creation and initialization of a database
ona PostgreSQL server; I already have an Ant task that searches for SQL files, orders them, and runs them against the
specifieddatabase server.  The database and all relative objects are set up in one step. 

So, I completely understand that I can write an SQL script that:
 1 - creates a function that wraps SQL code that inserts static data into dimension tables. 2 - executes that function
3- destroys that function 

But actually that is a bit weird, isn't it?

Thanks,


Daniel



Re: Executing plpgsql scripts using psql, is that possible?

From
Adrian Klaver
Date:
On Monday 16 January 2006 05:55 pm, Daniel CAUNE wrote:
> > -----Message d'origine-----
> > De : pgsql-sql-owner@postgresql.org [mailto:pgsql-sql-
> > owner@postgresql.org] De la part de John DeSoi
> > Envoyé : lundi 16 janvier 2006 08:51
> > À : Daniel CAUNE
> > Cc : pgsql-sql@postgresql.org
> > Objet : Re: [SQL] Executing plpgsql scripts using psql, is that possible?
> >
> > On Jan 16, 2006, at 5:35 AM, Daniel CAUNE wrote:
> > > I would like to write some administration plpgsql scripts that
> > > populate some tables (dimension tables) and to execute them using
> > > psql.  I’m not sure that is possible with psql as it is with Oracle
> > > sqlplus or SQL Server MSQuery:
> >
> > If you want to execute a plpgsql function from a file using psql,
> > just call it with SELECT. So your file might have:
> >
> > create or replace function my_function(params integer)
> > returns integer as $$
> > DECLARE
> >    V_MyObjectID bigint;
> > BEGIN
> >    V_MyObjectID := RegisterMyObject('a string', 'another string');
> >    AddObjectProperty(V_MyObjectID, 'a string');
> >    AddObjectProperty(V_MyObjectID, 'another string');
> > ....
> > END;
> > $$ language plpgsql;
> >
> >
> > SELECT my_function(1);
> >
> >
> > and then psql -f script.sql my_db
>
> Yes, but that requires creating a function while I would prefer not having
> do so, as I said in my previous mail: "I mean, without creating a function
> that wraps the whole, of course! :-)".  Why?  Actually this is not a
> function; this is a script that inserts static data into dimension tables
> such as Country, Language, etc.
>
> I have several scripts responsible for creating the database and all the
> objects (tables, views, constraints, indexes, user-defined functions, etc.)
> of my project.  I would like to have some other scripts to initialize
> dimension tables, i.e. inserting static data in those tables.  The idea is
> to automate the whole creation and initialization of a database on a
> PostgreSQL server; I already have an Ant task that searches for SQL files,
> orders them, and runs them against the specified database server.  The
> database and all relative objects are set up in one step.
>
> So, I completely understand that I can write an SQL script that:
>
>   1 - creates a function that wraps SQL code that inserts static data into
> dimension tables. 2 - executes that function
>   3 - destroys that function
>
> But actually that is a bit weird, isn't it?
>
> Thanks,
>
>
> Daniel
>
>
> ---------------------------(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
If you want to use plpgsql it will need to be within a function. In your reply
you mention creating user-defined functions as part of the set up procedure.
It would not be weird to include the static data function as part of that
procedure and then call it to load the data. I see no reason to destroy the
function after use. If that is not the route you want to take you may want to
look at the following for information on using COPY to load data from a file
into a table-
www.postgresql.org/docs/8.1/interactive/sql-copy.html

--
Adrian Klaver
aklaver@comcast.net


Re: Executing plpgsql scripts using psql, is that possible?

From
John DeSoi
Date:
Daniel,

On Jan 16, 2006, at 8:55 PM, Daniel CAUNE wrote:

> Yes, but that requires creating a function while I would prefer not  
> having do so, as I said in my previous mail: "I mean, without  
> creating a function that wraps the whole, of course! :-)".  Why?   
> Actually this is not a function; this is a script that inserts  
> static data into dimension tables such as Country, Language, etc.

Sorry I misunderstood the question.


> So, I completely understand that I can write an SQL script that:
>
>   1 - creates a function that wraps SQL code that inserts static  
> data into dimension tables.
>   2 - executes that function
>   3 - destroys that function
>
> But actually that is a bit weird, isn't it?

\copy is the easiest way in psql to populate tables.

If you need more control, maybe copy the data to temp tables and then  
write plpgsql as needed to insert the data into the final tables.




John DeSoi, Ph.D.
http://pgedit.com/
Power Tools for PostgreSQL



Re: Executing plpgsql scripts using psql, is that possible?

From
Daniel CAUNE
Date:
> If you want to use plpgsql it will need to be within a function. In your
> reply
> you mention creating user-defined functions as part of the set up
> procedure.
> It would not be weird to include the static data function as part of that
> procedure and then call it to load the data. I see no reason to destroy
> the
> function after use. If that is not the route you want to take you may want
> to
> look at the following for information on using COPY to load data from a
> file
> into a table-
> www.postgresql.org/docs/8.1/interactive/sql-copy.html
> 

Yes, COPY may be an interesting option too.

Thanks!



Characters that needs escape characters when inserting to database

From
"Christian Paul B. Cosinas"
Date:
Hi,

Can anyone give me a list of characters that needs to be preceded by an
escape character before inserting to database.

Aside from characters listed below what are the other characters?

"\"
"'"

Thanks


I choose Polesoft Lockspam to fight spam, and you?
http://www.polesoft.com/refer.html    



Re: Characters that needs escape characters when inserting to database

From
Michael Glaesemann
Date:
On Jan 18, 2006, at 7:21 , Christian Paul B. Cosinas wrote:

> Can anyone give me a list of characters that needs to be preceded  
> by an
> escape character before inserting to database.

Take a look at this documentation on string constants. It should  
answer the questions you have.
http://www.postgresql.org/docs/current/interactive/sql- 
syntax.html#SQL-SYNTAX-STRINGS

Michael Glaesemann
grzm myrealbox com





Re: Characters that needs escape characters when inserting to database

From
Michael Fuhr
Date:
On Tue, Jan 17, 2006 at 04:20:23PM +0900, Michael Glaesemann wrote:
> On Jan 18, 2006, at 7:21 , Christian Paul B. Cosinas wrote:
> >Can anyone give me a list of characters that needs to be preceded  
> >by an escape character before inserting to database.
> 
> Take a look at this documentation on string constants. It should  
> answer the questions you have.
> http://www.postgresql.org/docs/current/interactive/sql-syntax.html#SQL-SYNTAX-STRINGS

Out of curiosity, why are you asking?  Unless you're implementing
some low-level interface to the database you shouldn't need to worry
about escaping strings; just use your API's quote/escape (or whatever)
function or its placeholder mechanism (if it has one).  If you're
using an interface that doesn't have any of these capabilities, what
is it?  Some people might want to avoid it ;-)

-- 
Michael Fuhr


Re: Characters that needs escape characters when inserting to database

From
"Christian Paul B. Cosinas"
Date:
I am using Visual Basic as the front end.
I connect to postgresql database through ODBC.
I encounter some error when I insert value to a field.
The error is "syntax error"
Which make me think that there are other characters that needs an escape
chcracter.

Cheers.

-----Original Message-----
From: Michael Fuhr [mailto:mike@fuhr.org]
Sent: Tuesday, January 17, 2006 9:57 AM
To: Michael Glaesemann
Cc: Christian Paul B. Cosinas; pgsql-sql@postgresql.org
Subject: Re: [SQL] Characters that needs escape characters when inserting to
database

On Tue, Jan 17, 2006 at 04:20:23PM +0900, Michael Glaesemann wrote:
> On Jan 18, 2006, at 7:21 , Christian Paul B. Cosinas wrote:
> >Can anyone give me a list of characters that needs to be preceded by 
> >an escape character before inserting to database.
> 
> Take a look at this documentation on string constants. It should 
> answer the questions you have.
> http://www.postgresql.org/docs/current/interactive/sql-syntax.html#SQL
> -SYNTAX-STRINGS

Out of curiosity, why are you asking?  Unless you're implementing some
low-level interface to the database you shouldn't need to worry about
escaping strings; just use your API's quote/escape (or whatever) function or
its placeholder mechanism (if it has one).  If you're using an interface
that doesn't have any of these capabilities, what is it?  Some people might
want to avoid it ;-)

--
Michael Fuhr


I choose Polesoft Lockspam to fight spam, and you?
http://www.polesoft.com/refer.html