Re: Pattern match against array elements? - Mailing list pgsql-general

From Israel Brewster
Subject Re: Pattern match against array elements?
Date
Msg-id 0C125A4C-066D-43D3-8AAC-A3588558B5FC@ravnalaska.net
Whole thread Raw
In response to Re: Pattern match against array elements?  (Jeff Janes <jeff.janes@gmail.com>)
List pgsql-general

-----------------------------------------------
Israel Brewster
Systems Analyst II
Ravn Alaska
5245 Airport Industrial Rd
Fairbanks, AK 99709
(907) 450-7293
-----------------------------------------------



On Oct 12, 2015, at 11:50 AM, Jeff Janes <jeff.janes@gmail.com> wrote:

On Mon, Oct 12, 2015 at 11:39 AM, Tom Lane <tgl@sss.pgh.pa.us> wrote:
Jeff Janes <jeff.janes@gmail.com> writes:
> On Mon, Oct 12, 2015 at 10:58 AM, Israel Brewster <israel@ravnalaska.net>
> wrote:
>> My first thought was to do something like this:
>>
>> SELECT * FROM (SELECT lognum,array_agg(flightnum) as flightnums FROM logs
>> GROUP BY lognum) s1 WHERE '8%' like ANY(flightnums);
>>
>> But while this doesn't give an error, it also doesn't return any results.
>> I'm guessing that this is because the wildcard is on the left of the
>> operator, and needs to be on the right.

> Right.  The LIKE operator does not have a commutator by default.  (And if
> you created one for it, it could not use an index in this case.)

Well, it couldn't use an index anyway, given that the query as written
wants to collect groups if *any* member is LIKE '8%', rather than
restricting the data to such flightnums before aggregation occurs.

I was jumping ahead a bit here.  I was thinking of the case where the aggregation query was made a materialized view with a gin index on the aggregated column.  It is not obvious that a "scalar operator ANY(flightnums)" can't use an index on array_column, but it can't.  My interest was more in the % operator from pg_trgm, but also the normal text = operator would be nice to use here (as opposed to the much uglier <@ or @> in which the scalar needs to be wrapped into a degenerate array.)
 


Personally I'd suggest building a commutator operator (just need a
one-liner SQL or plpgsql function as infrastructure) and away you go.

Right, something like:

create function like_rev (text, text) returns boolean as $$ select $2 like $1 $$ language SQL;

create operator ~~~~ (procedure = like_rev,  leftarg=text, rightarg=text);

...which actually works perfectly for my use case. No, it doesn't use an index, however even the worst case scenario on my data, where that is the ONLY criteria given, "only" takes about 10 seconds. Yes, that is a "long" time, however a) 99% of the time there will be other criteria used as well, drastically reducing the result set and speeding the query, and b) the query is used as part of a report generator, for which there isn't really a problem if the user has to wait a few seconds. 


You can explicitly specify the commutator but it doesn't seem to be necessary to do so:

create operator ~~~~ (procedure = like_rev,  leftarg=text, rightarg=text,commutator = ~~ );



> I think you're best bet is to do a subquery against the unaggregated table.

> select * from aggregated a where exists
>   (select 1 from unaggregated ua where a.lognum=ua.lognum and flightnum
> like '8%')

That would work too, but not sure about performance relative to the other
way.

In my experience, if the subselect can use an index on the LIKE and if '8%' is rare, then using the subselect will be vastly better.  And if it is indexable or not rare, it is still likely to be better, or at least not worse by much. Disaggregating every array for every row to do the ANY is pretty inefficient.  Particularly if you are not using a materialized view, and so have to first aggregate it.

Of course good enough is good enough, so if scalar ~~~~ ANY(array)  is good enough...

Exactly. I think I could make the sub-select work, with some tweaking, and as it could well improve performance noticeably I may well spend some time on it, but the commutator operator "just works" and integrates quite nicely with my existing query structure.

Thanks for the help!

 
Cheers,

Jeff

Attachment

pgsql-general by date:

Previous
From: Alvaro Herrera
Date:
Subject: Re: Understanding "seq scans"
Next
From: David Rowley
Date:
Subject: Re: Merge join vs merge semi join against primary key