Keep specialized query pairs, or use single more general but more complex one - Mailing list pgsql-general

From Dominique Devienne
Subject Keep specialized query pairs, or use single more general but more complex one
Date
Msg-id CAFCRh-9SDUvcrF_RigOzXsbOm=8mHmzy2OSC1ejQNcjmfXXM_Q@mail.gmail.com
Whole thread Raw
Responses Re: Keep specialized query pairs, or use single more general but more complex one
Re: Keep specialized query pairs, or use single more general but more complex one
List pgsql-general
Hi,

We have a few dozen queries involving grandparent, parent, child table triplets,
to implement a pre-existing API on top of PostgreSQL. That API is not SQL-based
nor SQL "friendly" either, that's why we detect patterns in the APIs inputs, to use
different SQL queries, as (important) optimizations, thus the "dozen of queries" above.

But now we have a new requirement, for "fuzzy find". I.e. the client can ask for names
which are not the exact in-DB names, but also aliases of those names. That requires a
different query, which is a bit more complex. Here's an example:

# existing "exact-name" query
select ...
from child c
join parent s on s.id = c.parent
join grantparent w on w.id = s.parent
where w.name = $1
and s.name = $2
and c.name = $3

# new "aliased name" query
select ...
from child c    
join parent s on s.id = c.parent    
join grantparent w on w.id = s.parent    
join unnest($3::text[]) with ordinality as aliases(name, ord) on c.name = aliases.name    
where w.name = $1    
and s.name = $2    
order by aliases.ord    
limit 1

Notice the limit 1, i.e. this is still a scalar query, since name or (parent, name) are UNIQUE,
and the fact the alias query is ordered, the first match in alias order is "preferred".

Given the above, it is obvious that if we stick the exact name in front of its aliases, and use only the 2nd query, this is functionally equivalent (if it isn't, please let us know!).

And from a maintenance perspective, not doubling our queries sounds like a good thing.

But then, I do worry about performance. Will the second more complex query be planned just as well of the 1st one?

We have two types of clients (apps) for that API:
* The first type never relies on fuzzy-find.
* While the second type relies extensively on it.
Thus I don't want to penalize the first type, over the second.

I'd appreciate an expert opinion on planning (Tom? Andrew?),
in the context of unnest+order by ordinal+limit 1 with UNIQUE constraints,
versus the simpler 3-way-join with equality constraints, to base my decision on.

Thanks, --DD

PS: We are v16+ based.

pgsql-general by date:

Previous
From: Dominique Devienne
Date:
Subject: Re: #XX000: ERROR: tuple concurrently updated
Next
From: Matthias Apitz
Date:
Subject: COLLATION update in 13.1