Re: Functions and Indexes

From: Laurenz Albe <laurenz(dot)albe(at)cybertec(dot)at>
To: Moreno Andreo <moreno(dot)andreo(at)evolu-s(dot)it>, pgsql-general(at)lists(dot)postgresql(dot)org
Subject: Re: Functions and Indexes
Date: 2024-11-18 19:05:31
Message-ID: 61cb94a962667788c9c09107fa9937300e54d3cd.camel@cybertec.at
Views: Raw Message | Whole Thread | Download mbox | Resend email
Thread:
Lists: pgsql-general

On Mon, 2024-11-18 at 15:37 +0100, Moreno Andreo wrote:
> I'm creating indexes for some tables, and I came across a doubt.
>
> If a column appears in the WHERE clause (and so it should be placed in
> index), in case it is "processed" in a function (see below), is it
> possible to insert this function to further narrow down things?
>
> Common index:
> SELECT foo1, foo2 FROM bar WHERE foo1 = 2
> CREATE index bar1_idx ON bar USING btree(foo1);
>
> What about if query becomes
> SELECT foo1, foo2 FROM bar WHERE (POSITION(foo1 IN 'blah blah') >0)

You could create an index like

CREATE INDEX ON bar (position(foo1 IN 'blah blah'));

Alternatively, you could have a partial index:

CREATE INDEX ON bar (foo1) INCLUDE (foo2)
WHERE position(foo1 IN 'blah blah') > 0;

> Second question: I 've seen contrasting opinions about putting JOIN
> parameters (ON a.field1 = b.field2) in an index and I'd like to know
> your thoughts.

That depends on the join strategy PostgreSQL chooses.
You can use EXPLAIN to figure out the join strategy.
This article should explain details:
https://www.cybertec-postgresql.com/en/join-strategies-and-performance-in-postgresql/

Yours,
Laurenz Albe

In response to

Responses

Browse pgsql-general by date

  From Date Subject
Next Message Maxime Legault-Venne 2024-11-18 21:24:04 Default session role broken in PostgreSQL 14.14?
Previous Message Laurenz Albe 2024-11-18 18:57:18 Re: work_mem RAM Accounting in PostgreSQL