Re: functions in WHERE clause

From: sramsay(at)uga(dot)edu
To: pgsql-sql(at)postgresql(dot)org
Subject: Re: functions in WHERE clause
Date: 2006-03-05 20:10:43
Message-ID: 20060305201043.GA14773@cantor.english.uga.edu
Views: Raw Message | Whole Thread | Download mbox | Resend email
Thread:
Lists: pgsql-sql

On Sun, Mar 05, 2006 at 11:38:46AM -0800, Stephan Szabo wrote:
> > But imagine instead that this function is more generic. You know
> > that you're trying to get something that's equal to x and equal to
> > y, but you don't know (until the function is called) what those
> > rvalues should be. In other words, it's the 42 and the 47 that you
> > don't know until runtime -- you always know what columns your
> > searching on.
>
> Then you need to pass those in as well as something representing the row
> that's being tested -- where clauses are filters on rows. The whole row
> representation might be better than columns for some cases.
>
> For example:
>
> create table tt1(a int, b int);
> create function f1(tt1, int) returns bool as 'select $1.a = $2' language
> 'sql';
>
> select * from tt1 where f1(tt1, 1);

Eureka! That does it:

CREATE OR REPLACE FUNCTION xpath(event, lquery) RETURNS bool AS $$
SELECT $1.ltree ~ $2;
$$ LANGUAGE SQL;

And it's fast (the event table is a view)!

Interestingly, this version is very slow:

CREATE OR REPLACE FUNCTION xpath(event, lquery) RETURNS bool AS
$$
BEGIN
RETURN $1.ltree ~ $2;
END
$$ LANGUAGE plpgsql STABLE;

EXPLAIN shows lots of sequential scans when you try to do it this
way. No inlining, perhaps?

I guess I am still a little confused as to why you have to pass the
table in as a parameter -- why you can't just do:

RETURN event.ltree ~ $2;

But I'll live . . .

Thanks to one and all for the very generous assistance. I have
learned much.

Steve

> The other option is to do this as a set returning function in the first
> place rather than trying to do a wierd where clause thing.

Mostly for syntactic clarity on the caller's end, but I understand what
you're saying.

--
Stephen Ramsay
Assistant Professor
Department of English
University of Georgia
email: sramsay(at)uga(dot)edu
web: http://cantor.english.uga.edu/
PGP Public Key ID: 0xA38D7B11

In response to

Responses

Browse pgsql-sql by date

  From Date Subject
Next Message Stephan Szabo 2006-03-05 20:23:42 Re: functions in WHERE clause
Previous Message Stephan Szabo 2006-03-05 19:38:46 Re: functions in WHERE clause