Thread: Creating a session variable in Postgres

Creating a session variable in Postgres

From
"Nagib Abi Fadel"
Date:
Is it possible to create a session variable for each user in Postresql ??
 
Thx

Re: Creating a session variable in Postgres

From
Bill Moran
Date:
On Wed, 2 Jun 2004 16:00:18 +0200
"Nagib Abi Fadel" <nagib.abi-fadel@usj.edu.lb> wrote:

> Is it possible to create a session variable for each user in Postresql ??

I was just thinking that the term "session variable" is like the word "love" in
that it means something different to everyone.

That being said, I can't think of any definition of "session variable" that
Postgres isn't capable of handling.  If you have a more specific meaning you
want to ask about, I suggest providing a scenerio, or otherwise more specific
question.

--
Bill Moran
Potential Technologies
http://www.potentialtech.com

Re: Creating a session variable in Postgres

From
Bruce Momjian
Date:
Nagib Abi Fadel wrote:
> Is it possible to create a session variable for each user in Postresql ??

No.  The best you can do is create a temp table and put a value in
there.

--
  Bruce Momjian                        |  http://candle.pha.pa.us
  pgman@candle.pha.pa.us               |  (610) 359-1001
  +  If your life is a hard drive,     |  13 Roberts Road
  +  Christ can be your backup.        |  Newtown Square, Pennsylvania 19073

Re: Creating a session variable in Postgres

From
Richard Huxton
Date:
Bruce Momjian wrote:
> Nagib Abi Fadel wrote:
>
>>Is it possible to create a session variable for each user in Postresql ??
>
>
> No.  The best you can do is create a temp table and put a value in
> there.

Would I be right in assuming that's going to be burning through OIDs
though (possibly an issue for a web-app with lots of short sessions).

--
   Richard Huxton
   Archonet Ltd

Re: Creating a session variable in Postgres

From
"Nagib Abi Fadel"
Date:
Well i thought about that but i don't feel like it is a clean way.

Actually i need to create a dynamic view depending on the user choice of a
certain variable via a web application.

Let's say for example the variable is called "X". The view is called
"t_view" and the temporary table is called "t_temp".
Each time a user connects to the web, the application will initialize the
variable X and it will be inserted into the temporary table t_temp.

i defined the following view: CREATE VIEW t_view as select * from SomeTable
where id = (select X from t_temp);
This didn't work first cause the temporary table does not exist.
So i created the temporary table then created the view "t_view" and then the
view was created (i kind of fooled the system).

Now every time a user access the web application he will choose a value for
X and the t_temp will be created and X inserted in it.

I solved my problem but it does not seem like a "clean way".

Any ideas ??



I have now a DYNAMIC view
----- Original Message -----
From: "Bruce Momjian" <pgman@candle.pha.pa.us>
To: "Nagib Abi Fadel" <nagib.abi-fadel@usj.edu.lb>
Cc: "generalpost" <pgsql-general@postgresql.org>
Sent: Wednesday, June 02, 2004 04:53 PM
Subject: Re: [GENERAL] Creating a session variable in Postgres


> Nagib Abi Fadel wrote:
> > Is it possible to create a session variable for each user in Postresql
??
>
> No.  The best you can do is create a temp table and put a value in
> there.
>
> --
>   Bruce Momjian                        |  http://candle.pha.pa.us
>   pgman@candle.pha.pa.us               |  (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 9: the planner will ignore your desire to choose an index scan if your
>       joining column's datatypes do not match


Re: Creating a session variable in Postgres

From
Manfred Koizar
Date:
On Thu, 3 Jun 2004 09:04:43 +0200, "Nagib Abi Fadel"
<nagib.abi-fadel@usj.edu.lb> wrote:
>Let's say for example the variable is called "X". The view is called
>"t_view" and the temporary table is called "t_temp".
>Each time a user connects to the web, the application will initialize the
>variable X and it will be inserted into the temporary table t_temp.

Sequence values are session-specific which is exactly the property
you're looking for.

    CREATE TABLE session (
        id SERIAL PRIMARY KEY,
        x text
    );

    CREATE VIEW mysession (x) AS
    SELECT x FROM session WHERE id=currval('session_id_seq');

    CREATE VIEW t_view AS
    SELECT *
      FROM SomeTable st INNER JOIN mysession s
        ON st.id = s.x;

At the start of a session you just

    INSERT INTO session (x) VALUES ('whatever');

From time to time you have to clean up the session table (delete old
entries, VACUUM ANALYSE).

If the value of your session variable X has no special meaning apart
from being unique, you don't need the session table, you just create a
sequence and use nextval/currval directly.

Or you might want to use pg_backend_pid().  It is documented here:
http://www.postgresql.org/docs/7.4/static/monitoring-stats.html.

Servus
 Manfred

Re: Creating a session variable in Postgres

From
Mike Mascari
Date:
Manfred Koizar wrote:
> On Thu, 3 Jun 2004 09:04:43 +0200, "Nagib Abi Fadel"
> <nagib.abi-fadel@usj.edu.lb> wrote:
>
>>Let's say for example the variable is called "X". The view is called
>>"t_view" and the temporary table is called "t_temp".
>>Each time a user connects to the web, the application will initialize the
>>variable X and it will be inserted into the temporary table t_temp.
>
> Sequence values are session-specific which is exactly the property
> you're looking for.
>
>     CREATE TABLE session (
>         id SERIAL PRIMARY KEY,
>         x text
>     );
>
>     CREATE VIEW mysession (x) AS
>     SELECT x FROM session WHERE id=currval('session_id_seq');
>
>     CREATE VIEW t_view AS
>     SELECT *
>       FROM SomeTable st INNER JOIN mysession s
>         ON st.id = s.x;
>
> At the start of a session you just
>
>     INSERT INTO session (x) VALUES ('whatever');

Couldn't one also do (this is untested - may include syntax errors):

-- Create a wrapper function for View usage

CREATE FUNCTION getValue() RETURNS text AS '

DECLARE

result text;

BEGIN

SELECT INTO result session_value
FROM session_data;

RETURN result;

END;

LANGUAGE 'plpgsql';

-- Create our View using our function

CREATE VIEW t_view AS
SELECT *
FROM foo
WHERE foo.key = getValue();

-- Now, upon connecting, the app does:

CREATE TEMPORARY TABLE session_data (value text);
INSERT INTO session_data VALUES ('Hello');

In this way, the table needn't exist until the first invocation of
getValue() upon the first access of the view, since the code will be
recompiled during the first access, correct?

Mike Mascari











Re: Creating a session variable in Postgres

From
Mike Nolan
Date:
> Would I be right in assuming that's going to be burning through OIDs
> though (possibly an issue for a web-app with lots of short sessions).

:climbing on soapbox:
If pg had a 64-bit system record ID like Oracle does, that'd
take care of this issue, at least until you managed to write
18 quintilliion (1.8e19) rows.  At a million rows a second, that'll
take you about 584,000 years.

Yeah, it costs some disk space, but disk space is cheap compared
to having to confront the OID rollover issue over and over again,
and not just because of bad database design.
:climbing off soapbox:
--
Mike Nolan

Re: Creating a session variable in Postgres

From
"Nagib Abi Fadel"
Date:
Thx guys Both Solutions works fine for me but which one is better (uses less
resources ?) ?
(Mike i tested your solution)

The use of sequence would require to clean up the table every N hour .
The use of temporary table wouldn't require any cleanup. Plus it won't use
any disk space (i suppose a temporary table wouldn't be written to disk
right ?).

Thx guys for your help.


----- Original Message -----
From: "Mike Mascari" <mascarm@mascari.com>
To: "Manfred Koizar" <mkoi-pg@aon.at>
Cc: "Nagib Abi Fadel" <nagib.abi-fadel@usj.edu.lb>; "Bruce Momjian"
<pgman@candle.pha.pa.us>; "generalpost" <pgsql-general@postgresql.org>
Sent: Thursday, June 03, 2004 04:55 PM
Subject: Re: [GENERAL] Creating a session variable in Postgres


> Manfred Koizar wrote:
> > On Thu, 3 Jun 2004 09:04:43 +0200, "Nagib Abi Fadel"
> > <nagib.abi-fadel@usj.edu.lb> wrote:
> >
> >>Let's say for example the variable is called "X". The view is called
> >>"t_view" and the temporary table is called "t_temp".
> >>Each time a user connects to the web, the application will initialize
the
> >>variable X and it will be inserted into the temporary table t_temp.
> >
> > Sequence values are session-specific which is exactly the property
> > you're looking for.
> >
> > CREATE TABLE session (
> > id SERIAL PRIMARY KEY,
> > x text
> > );
> >
> > CREATE VIEW mysession (x) AS
> > SELECT x FROM session WHERE id=currval('session_id_seq');
> >
> > CREATE VIEW t_view AS
> > SELECT *
> >   FROM SomeTable st INNER JOIN mysession s
> >     ON st.id = s.x;
> >
> > At the start of a session you just
> >
> > INSERT INTO session (x) VALUES ('whatever');
>
> Couldn't one also do (this is untested - may include syntax errors):
>
> -- Create a wrapper function for View usage
>
> CREATE FUNCTION getValue() RETURNS text AS '
>
> DECLARE
>
> result text;
>
> BEGIN
>
> SELECT INTO result session_value
> FROM session_data;
>
> RETURN result;
>
> END;
>
> LANGUAGE 'plpgsql';
>
> -- Create our View using our function
>
> CREATE VIEW t_view AS
> SELECT *
> FROM foo
> WHERE foo.key = getValue();
>
> -- Now, upon connecting, the app does:
>
> CREATE TEMPORARY TABLE session_data (value text);
> INSERT INTO session_data VALUES ('Hello');
>
> In this way, the table needn't exist until the first invocation of
> getValue() upon the first access of the view, since the code will be
> recompiled during the first access, correct?
>
> Mike Mascari
>
>
>
>
>
>
>
>
>
>
>
> ---------------------------(end of broadcast)---------------------------
> TIP 9: the planner will ignore your desire to choose an index scan if your
>       joining column's datatypes do not match


Re: Creating a session variable in Postgres

From
Manfred Koizar
Date:
On Thu, 3 Jun 2004 14:59:40 -0500 (CDT), Mike Nolan <nolan@gw.tssi.com>
wrote:
>disk space is cheap

Yes, but very often I/O is the bottleneck.

Servus
 Manfred

Re: Creating a session variable in Postgres

From
Manfred Koizar
Date:
On Fri, 4 Jun 2004 08:25:38 +0200, "Nagib Abi Fadel"
<nagib.abi-fadel@usj.edu.lb> wrote:
>The use of sequence would require to clean up the table every N hour .

Right.

>The use of temporary table wouldn't require any cleanup.

Wrong.  You would have to clean up the meta data, at least pg_class and
pg_attribute, maybe pg_index also.  For the price of one temp table you
can have several rows in a permanent table.

Servus
 Manfred

Re: Creating a session variable in Postgres

From
"Nagib Abi Fadel"
Date:
So considering those facts, it would be better to use the Sequence Method,
since it would only require cleaning up one table ....
Or is there anything else i am missing ???


----- Original Message -----
From: "Manfred Koizar" <mkoi-pg@aon.at>
To: "Nagib Abi Fadel" <nagib.abi-fadel@usj.edu.lb>
Cc: "Mike Mascari" <mascarm@mascari.com>; "Bruce Momjian"
<pgman@candle.pha.pa.us>; "generalpost" <pgsql-general@postgresql.org>
Sent: Friday, June 04, 2004 08:32 AM
Subject: Re: [GENERAL] Creating a session variable in Postgres


> On Fri, 4 Jun 2004 08:25:38 +0200, "Nagib Abi Fadel"
> <nagib.abi-fadel@usj.edu.lb> wrote:
> >The use of sequence would require to clean up the table every N hour .
>
> Right.
>
> >The use of temporary table wouldn't require any cleanup.
>
> Wrong.  You would have to clean up the meta data, at least pg_class and
> pg_attribute, maybe pg_index also.  For the price of one temp table you
> can have several rows in a permanent table.
>
> Servus
>  Manfred


Re: Creating a session variable in Postgres

From
"Nagib Abi Fadel"
Date:
Wait i did the following test:

SELECT count(*) from pg_class ;
 count
-------
   894

SELECT count(*) from pg_attribute ;
 count
-------
  7264

CREATE temp table temp_test (id integer);
CREATE TABLE

SELECT count(*) from pg_class ;
 count
-------
   895

SELECT count(*) from pg_attribute ;
count
-------
  7272

I DISCONNECTED AND RECONNECTED TO THE DATABASE:

NOW

SELECT count(*) from pg_class ;
 count
-------
   894

SELECT count(*) from pg_attribute ;
 count
-------
  7264

According to those results the meta_data for a temp table are automatically
removed when the table is destroyed

So ........



----- Original Message -----
From: "Nagib Abi Fadel" <nagib.abi-fadel@usj.edu.lb>
To: "Manfred Koizar" <mkoi-pg@aon.at>
Cc: "Mike Mascari" <mascarm@mascari.com>; "Bruce Momjian"
<pgman@candle.pha.pa.us>; "generalpost" <pgsql-general@postgresql.org>
Sent: Friday, June 04, 2004 11:14 AM
Subject: Re: [GENERAL] Creating a session variable in Postgres


> So considering those facts, it would be better to use the Sequence Method,
> since it would only require cleaning up one table ....
> Or is there anything else i am missing ???
>
>
> ----- Original Message -----
> From: "Manfred Koizar" <mkoi-pg@aon.at>
> To: "Nagib Abi Fadel" <nagib.abi-fadel@usj.edu.lb>
> Cc: "Mike Mascari" <mascarm@mascari.com>; "Bruce Momjian"
> <pgman@candle.pha.pa.us>; "generalpost" <pgsql-general@postgresql.org>
> Sent: Friday, June 04, 2004 08:32 AM
> Subject: Re: [GENERAL] Creating a session variable in Postgres
>
>
> > On Fri, 4 Jun 2004 08:25:38 +0200, "Nagib Abi Fadel"
> > <nagib.abi-fadel@usj.edu.lb> wrote:
> > >The use of sequence would require to clean up the table every N hour .
> >
> > Right.
> >
> > >The use of temporary table wouldn't require any cleanup.
> >
> > Wrong.  You would have to clean up the meta data, at least pg_class and
> > pg_attribute, maybe pg_index also.  For the price of one temp table you
> > can have several rows in a permanent table.
> >
> > Servus
> >  Manfred
>


Re: Creating a session variable in Postgres

From
Manfred Koizar
Date:
On Fri, 4 Jun 2004 11:23:30 +0200, "Nagib Abi Fadel"
<nagib.abi-fadel@usj.edu.lb> wrote:
>According to those results the meta_data for a temp table are automatically
>removed when the table is destroyed

Yes, but the dead tuples remain.  Try

    VACUUM VERBOSE pg_class;
    VACUUM VERBOSE pg_attribute;

Servus
 Manfred

Re: Creating a session variable in Postgres

From
Mike Mascari
Date:
Nagib Abi Fadel wrote:

> So considering those facts, it would be better to use the Sequence Method,
> since it would only require cleaning up one table ....
> Or is there anything else i am missing ???

It is becoming more of a toss-op. Prior to 7.4, the system indexes
would grow until a manual REINDEX was issued in a stand-alone
backend. In 7.4, the dead tuples remain, but at least can be re-used
once they've been marked that way by the occassional vacuum.
autovacuum will tend to make dead-tuple reclaimation transparent,
like Oracle.

The absolutely cheapest method is to write a pair of functions in
'C' that sets/gets a global variable:

#include "postgres.h"
#include "fmgr.h"

#define MAX_DATA 64

char session_data[MAX_DATA] = "";

PG_FUNCTION_INFO_V1(setvalue);

Datum setvalue(PG_FUNCTION_ARGS) {

  text *value;
  long len;

  value = PG_GETARG_TEXT_P(0);
  len = VARSIZE(value) - VARHDRSZ;
  if (len >= MAX_DATA) {
   elog(ERROR, "setvalue: value too long: %li", len);
  }
  memcpy(session_data, VARDATA(value), len);
  session_data[len] = 0;

  PG_RETURN_BOOL(true);

}

PG_FUNCTION_INFO_V1(getvalue);

Datum getvalue(PG_FUNCTION_ARGS) {

  text *result;
  long len;

  len = strlen(session_data) + VARHDRSZ;
  result = (text *) palloc(len);
  VARATT_SIZEP(result) = len;
  memcpy(VARDATA(result), session_data, len - VARHDRSZ);

  PG_RETURN_TEXT_P(result);

}

-- Compile

gcc  -c example.c -I/usr/include/pgsql/server
gcc -shared -o pgexample.so pgexample.o

-- Install somewhere PostgreSQL can get at it

cp pgexample.so /usr/local/mypglibs

-- Create the functions where path-to-lib is the path to
-- the shared library.

CREATE OR REPLACE FUNCTION setvalue(text) RETURNS boolean
AS '/usr/local/mypglibs/pgexample.so'
LANGUAGE 'C' WITH (isStrict);

CREATE OR REPLACE FUNCTION getvalue() RETURNS text
AS '/usr/local/mypglibs/pgexample.so'
LANGUAGE 'C' WITH (isStrict);

Now all you need to to is invoke setvalue() at the start of the
session, and build views around getvalue():

CREATE VIEW v_foo AS
  SELECT *
  FROM foo
  WHERE foo.key = getvalue();

At the start of a session:

SELECT setvalue('Mike Mascari was here');

Hope that helps,

Mike Mascari


Re: Creating a session variable in Postgres

From
"Nagib Abi Fadel"
Date:
Hi Thx Mike, it's the best solution i think.

But i did some modifications to the code since i need to store an integer I
wrote the following:

#include "postgres.h"
#include "fmgr.h"

int32 session_data;

PG_FUNCTION_INFO_V1(setvalue);

Datum setvalue(PG_FUNCTION_ARGS) {

               session_data = PG_GETARG_INT32(0);
               PG_RETURN_BOOL(true);

                }

PG_FUNCTION_INFO_V1(getvalue);
Datum getvalue(PG_FUNCTION_ARGS) {

     PG_RETURN_INT32(session_data);
     }

ANY COMMENTS ARE WELCOMED.

Najib.





----- Original Message -----
From: "Mike Mascari" <mascarm@mascari.com>
To: "Nagib Abi Fadel" <nagib.abi-fadel@usj.edu.lb>
Cc: "Manfred Koizar" <mkoi-pg@aon.at>; "Bruce Momjian"
<pgman@candle.pha.pa.us>; "generalpost" <pgsql-general@postgresql.org>
Sent: Friday, June 04, 2004 11:21 AM
Subject: Re: [GENERAL] Creating a session variable in Postgres


> Nagib Abi Fadel wrote:
>
> > So considering those facts, it would be better to use the Sequence
Method,
> > since it would only require cleaning up one table ....
> > Or is there anything else i am missing ???
>
> It is becoming more of a toss-op. Prior to 7.4, the system indexes
> would grow until a manual REINDEX was issued in a stand-alone
> backend. In 7.4, the dead tuples remain, but at least can be re-used
> once they've been marked that way by the occassional vacuum.
> autovacuum will tend to make dead-tuple reclaimation transparent,
> like Oracle.
>
> The absolutely cheapest method is to write a pair of functions in
> 'C' that sets/gets a global variable:
>
> #include "postgres.h"
> #include "fmgr.h"
>
> #define MAX_DATA 64
>
> char session_data[MAX_DATA] = "";
>
> PG_FUNCTION_INFO_V1(setvalue);
>
> Datum setvalue(PG_FUNCTION_ARGS) {
>
>   text *value;
>   long len;
>
>   value = PG_GETARG_TEXT_P(0);
>   len = VARSIZE(value) - VARHDRSZ;
>   if (len >= MAX_DATA) {
>    elog(ERROR, "setvalue: value too long: %li", len);
>   }
>   memcpy(session_data, VARDATA(value), len);
>   session_data[len] = 0;
>
>   PG_RETURN_BOOL(true);
>
> }
>
> PG_FUNCTION_INFO_V1(getvalue);
>
> Datum getvalue(PG_FUNCTION_ARGS) {
>
>   text *result;
>   long len;
>
>   len = strlen(session_data) + VARHDRSZ;
>   result = (text *) palloc(len);
>   VARATT_SIZEP(result) = len;
>   memcpy(VARDATA(result), session_data, len - VARHDRSZ);
>
>   PG_RETURN_TEXT_P(result);
>
> }
>
> -- Compile
>
> gcc  -c example.c -I/usr/include/pgsql/server
> gcc -shared -o pgexample.so pgexample.o
>
> -- Install somewhere PostgreSQL can get at it
>
> cp pgexample.so /usr/local/mypglibs
>
> -- Create the functions where path-to-lib is the path to
> -- the shared library.
>
> CREATE OR REPLACE FUNCTION setvalue(text) RETURNS boolean
> AS '/usr/local/mypglibs/pgexample.so'
> LANGUAGE 'C' WITH (isStrict);
>
> CREATE OR REPLACE FUNCTION getvalue() RETURNS text
> AS '/usr/local/mypglibs/pgexample.so'
> LANGUAGE 'C' WITH (isStrict);
>
> Now all you need to to is invoke setvalue() at the start of the
> session, and build views around getvalue():
>
> CREATE VIEW v_foo AS
>   SELECT *
>   FROM foo
>   WHERE foo.key = getvalue();
>
> At the start of a session:
>
> SELECT setvalue('Mike Mascari was here');
>
> Hope that helps,
>
> Mike Mascari
>
>
> ---------------------------(end of broadcast)---------------------------
> TIP 5: Have you checked our extensive FAQ?
>
>                http://www.postgresql.org/docs/faqs/FAQ.html