Re: [PERFORM] Hibernate generated query slow compared to 'equivalent' hand written one

2016-10-14 Thread Tom Lane
Kyle Moser  writes:
> Thanks so much for the response. They are the same data, that was due to
> deidentification on my part. So even though the second Hibernate query says
> "index only scan" (in addition to the filter, as you said) it is
> inefficient. Why does it say index only scan if it can't use the index due
> to the types being numeric and the index being bigint? (I suppose my
> question here is how to interpret the output properly - so I don't make
> this mistake again).

The key thing to notice about that is that it says "Filter" not
"Index Cond".  That means it's pulling data from the index but
not making use of the index's search ability --- that is, it's
scanning every index entry and applying the "IN" condition to the
value, in much the same way as it'd do with heap entries in a plain
seqscan.  That's a pretty silly plan, which in most cases you would
not get if you hadn't forced it.

regards, tom lane


-- 
Sent via pgsql-performance mailing list (pgsql-performance@postgresql.org)
To make changes to your subscription:
http://www.postgresql.org/mailpref/pgsql-performance


Re: [PERFORM] Hibernate generated query slow compared to 'equivalent' hand written one

2016-10-14 Thread Kyle Moser
Tom,

Thanks so much for the response. They are the same data, that was due to
deidentification on my part. So even though the second Hibernate query says
"index only scan" (in addition to the filter, as you said) it is
inefficient. Why does it say index only scan if it can't use the index due
to the types being numeric and the index being bigint? (I suppose my
question here is how to interpret the output properly - so I don't make
this mistake again).

On Fri, Oct 14, 2016 at 1:46 PM, Tom Lane  wrote:

> Kyle Moser  writes:
> > The depesz link for explain (analyze, buffers) is shown below for 3
> > different queries. The first two queries show a log dump of the postgres
> > log, showing a query that was generated by Java Hibernate. The third
> query
> > was one I wrote and ran in pgadmin that I think is similar to what
> > Hibernate is doing.
>
> It's not all that similar: according to the EXPLAIN output, the condition
> Hibernate is generating is
>
> Filter: ((FK_USER)::numeric = ANY ('{213,382,131,...,717}'::numeric[]))
>
> whereas your handwritten query is generating
>
> Index Cond: (fk_user = ANY ('{70,150,1248,1269,1530,...,
> 199954}'::bigint[]))
>
> IOW, Hibernate is telling the server that the parameters it's supplying
> are NUMERIC not INTEGER, which results in a query using numeric_eq, which
> can't be indexed by a bigint index.
>
> If you can't find a hammer big enough to persuade Hibernate that it's
> dealing with integers/bigints rather than numerics, you could probably
> regain most of the performance by creating an index on (FK_USER::numeric).
>
> BTW, why is one of your EXPLAINs showing the identifiers in upper case
> and the other in lower case?  One could be forgiven for wondering if
> these were really against the same data.
>
> regards, tom lane
>


Re: [PERFORM] Hibernate generated query slow compared to 'equivalent' hand written one

2016-10-14 Thread Tom Lane
Kyle Moser  writes:
> The depesz link for explain (analyze, buffers) is shown below for 3
> different queries. The first two queries show a log dump of the postgres
> log, showing a query that was generated by Java Hibernate. The third query
> was one I wrote and ran in pgadmin that I think is similar to what
> Hibernate is doing.

It's not all that similar: according to the EXPLAIN output, the condition
Hibernate is generating is

Filter: ((FK_USER)::numeric = ANY ('{213,382,131,...,717}'::numeric[]))

whereas your handwritten query is generating

Index Cond: (fk_user = ANY ('{70,150,1248,1269,1530,...,199954}'::bigint[]))

IOW, Hibernate is telling the server that the parameters it's supplying
are NUMERIC not INTEGER, which results in a query using numeric_eq, which
can't be indexed by a bigint index.

If you can't find a hammer big enough to persuade Hibernate that it's
dealing with integers/bigints rather than numerics, you could probably
regain most of the performance by creating an index on (FK_USER::numeric).

BTW, why is one of your EXPLAINs showing the identifiers in upper case
and the other in lower case?  One could be forgiven for wondering if
these were really against the same data.

regards, tom lane


-- 
Sent via pgsql-performance mailing list (pgsql-performance@postgresql.org)
To make changes to your subscription:
http://www.postgresql.org/mailpref/pgsql-performance