Re: index on to_char(created, 'YYYY') doesn't work

From: Achilleus Mantzios <achill(at)matrix(dot)gatewaynet(dot)com>
To: Andreas Joseph Krogh <andreak(at)officenet(dot)no>
Cc: pgsql-sql(at)postgresql(dot)org
Subject: Re: index on to_char(created, 'YYYY') doesn't work
Date: 2003-01-15 20:02:46
Message-ID: Pine.LNX.4.44.0301151759230.3008-100000@matrix.gatewaynet.com
Views: Raw Message | Whole Thread | Download mbox | Resend email
Thread:
Lists: pgsql-sql

On Wed, 15 Jan 2003, Andreas Joseph Krogh wrote:

> -----BEGIN PGP SIGNED MESSAGE-----
> Hash: SHA1
>
> On Wednesday 15 January 2003 18:55, Achilleus Mantzios wrote:
> > On Wed, 15 Jan 2003, Andreas Joseph Krogh wrote:
> > > -----BEGIN PGP SIGNED MESSAGE-----
> > > Hash: SHA1
> > >
> > > On Wednesday 15 January 2003 16:12, you wrote:
> > > > On Wed, 15 Jan 2003, Andreas Joseph Krogh wrote:
> > > > > -----BEGIN PGP SIGNED MESSAGE-----
> > > > > Hash: SHA1
> > > > >
> > > > > On Wednesday 15 January 2003 11:37, you wrote:
> > > > > > The following does not work:
> > > > > >
> > > > > > create index session_u_idx on session (to_char(created, 'YYYY'));
> > > > > > ERROR: parser: parse error at or near "'YYYY'" at character 57
> > > > > >
> > > > > > Can I make a function to do this and index using the result of that
> > > > > > funtion? Do anyone have an example of such a function?
> > > > >
> > > > > I tried the following function:
> > > > > - -----------------------------------------------------------------
> > > > > create function drus (timestamp) returns varchar AS'
> > > > > DECLARE
> > > > > str_created VARCHAR;
> > > > > created ALIAS FOR $1;
> > > > > BEGIN
> > > > > str_created:= to_char(created, ''YYYY'');
> > > > > RETURN str_created;
> > > > > END;
> > > > > ' LANGUAGE 'plpgsql';
> > > >
> > > > add
> > > > WITH (iscachable)
> > >
> > > Thank you, not _that_ works:-)
> > > But now this doesn't work:
> > > create index session_u_idx on session (drus(created), username);
> >
> > Functinal indexes are single column indexes.
> >
> > Why dont you change your function to:
> >
> > create function drus (timestamp,varchar) returns varchar A
> >
> > and return the concatenation of to_char(created, ''YYYY'')||$2
> >
> > and then create the index as usual (passing the date and the username
> > as params to your function)????
>
> OK, thank you.
> Let me explain what I want to do:

You didnt try it!!

Change your to_char(created, ''YYYY'')||$2 to
to_char(created, ''YYYY'')||(coalesce($2,'''')
(provided there is no user named mister '' :)

then perform your query like:

select to_char(created, 'IW') as week, count(session_id) from session
WHERE drus(created,username) = '2002' group by week ORDER BY
week;

do a explain analyze to see index and performance issues.

> I have the following schema for gathering statistics from the web:
>
> CREATE TABLE session (
> session_id varchar(256) NOT NULL PRIMARY KEY,
> created timestamp DEFAULT 'now' NOT NULL,
> last_accessed timestamp NOT NULL,
> destroyed timestamp NOT NULL,
> username varchar -- Allow sessions from not logged in users
> );
>
> create or replace function drus (timestamp) returns varchar AS'
> DECLARE
> str_created VARCHAR;
> created ALIAS FOR $1;
> BEGIN
> str_created:= to_char(created, ''YYYY'');
> RETURN str_created;
> END;
> ' LANGUAGE 'plpgsql' WITH (iscachable);
>
> create index session_u_idx on session (drus(created)) where username is null;
>
> Now I want to get statistics for number of hits pr. week where users are not
> lnogged in(username IS NULL) for the year 2002:
>
> select to_char(created, 'IW') as week, count(session_id) from session WHERE
> username IS NULL and drus(created) = '2002' group by week ORDER BY week;
> week | count
> - ------+-------
> 01 | 6321
> 18 | 74
> 19 | 12153
> 20 | 17125
> 21 | 22157
> 22 | 25316
> 23 | 24265
> 24 | 26234
> 25 | 28583
> 26 | 29156
> 27 | 28335
> 28 | 23587
> 29 | 23203
>
> This table is quite large(900 000 rows) and the query takes several minutes to
> run, which makes the browser timeout.
> Do I have a design-issue here, should I rather batch-generate the stats in its
> own table so I don't have to process all the data(900 000 rows) each time.
>
> Is there any way to optimize/rewrite this query? Is the use of to_char on the
> timestamp wrong, should I use another comparation method for getting the year
> 2002?
>
> - --
> Andreas Joseph Krogh <andreak(at)officenet(dot)no>
> There will always be someone who agrees with you
> but is, inexplicably, a moron.
>
> gpg public_key: http://dev.officenet.no/~andreak/public_key.asc
> -----BEGIN PGP SIGNATURE-----
> Version: GnuPG v1.0.7 (GNU/Linux)
>
> iD8DBQE+JXiPUopImDh2gfQRAlf/AJ9xlcUDqa7NcXghtse8PAqQxkf1lACdEGxH
> vBXYxoFZnS6J35iQGw+14wE=
> =xCVY
> -----END PGP SIGNATURE-----
>
>
> ---------------------------(end of broadcast)---------------------------
> TIP 1: subscribe and unsubscribe commands go to majordomo(at)postgresql(dot)org
>

==================================================================
Achilleus Mantzios
S/W Engineer
IT dept
Dynacom Tankers Mngmt
Nikis 4, Glyfada
Athens 16610
Greece
tel: +30-10-8981112
fax: +30-10-8981877
email: achill(at)matrix(dot)gatewaynet(dot)com
mantzios(at)softlab(dot)ece(dot)ntua(dot)gr

In response to

Responses

Browse pgsql-sql by date

  From Date Subject
Next Message Ross J. Reedstrom 2003-01-15 20:07:41 Re: sort by relevance
Previous Message Tomasz Myrta 2003-01-15 19:59:43 Re: lost on self joins