Getting an index scan to be a parallel index scan
Hello,
I'm trying to get the following query to use a plan with parallelism, but I
haven't been successful and would like some advice.
The schema and table that I'm using is this:
CREATE TABLE testing(
id INT,
info INT,
data_one TEXT,
data_two TEXT,
primary key(id, info)
);
INSERT INTO testing(id, info, data_one, data_two)
SELECT idx, idx, md5(random()::text), md5(random()::text)
FROM generate_series(1,1000) idx;
Then the query that I'm trying to run is this (I'll include the full query
at the very end of the email because it is long:
select * from testing where id in (1608377,5449811, ... <1000 random ids>
,4654284,3558460);
Essentially I have a list of 1000 ids and I would like the rows for all of
those ids.
This seems like it would be pretty easy to parallelize, if you have X
threads then you would split the list of IDs into 1000/X sub lists and give
one to each thread to go find the rows for ids in the given list. Even
when I use the following configs I don't get a query plan that actually
uses any parallelism:
psql (15.1 (Debian 15.1-1.pgdg110+1))
Type "help" for help.
postgres=# show max_parallel_workers;
max_parallel_workers
--
8
(1 row)
postgres=# set max_parallel_workers_per_gather = 8;
SET
postgres=# set parallel_setup_cost = 0;
SET
postgres=# set parallel_tuple_cost = 0;
SET
postgres=# set force_parallel_mode = on;
SET
postgres=# explain select * from testing where id in (1608377,5449811, ...
... ,4654284,3558460);
QUERY PLAN
---
Gather (cost=0.43..6138.81 rows=1000 width=74)
Workers Planned: 1
Single Copy: true
-> Index Scan using testing_pkey on testing (cost=0.43..6138.81
rows=1000 width=74)
Index Cond: (id = ANY ('{1608377,5449811 ...
... 4654284,3558460}'::integer[]))
(5 rows)
postgres=# explain (analyze, buffers) select * from testing where id in
(1608377,5449811, ... ... ,4654284,3558460);
QUERY PLAN
---
Gather (cost=0.43..6138.81 rows=1000 width=74) (actual
time=22.388..59.860 rows=1000 loops=1)
Workers Planned: 1
Workers Launched: 1
Single Copy: true
Buffers: shared hit=4003
-> Index Scan using testing_pkey on testing (cost=0.43..6138.81
rows=1000 width=74) (actual time=0.443..43.660 rows=1000 loops=1)
Index Cond: (id = ANY ('{1608377,5449811 ...
... 4654284,3558460}'::integer[]))
Buffers: shared hit=4003
Planning Time: 3.101 ms
Execution Time: 60.211 ms
(10 rows)
postgres=# explain select * from testing;
QUERY PLAN
--
Gather (cost=0.00..153334.10 rows=1050 width=74)
Workers Planned: 5
-> Parallel Seq Scan on testing (cost=0.00..153334.10 rows=210
width=74)
(3 rows)
That last query is just to show that I can get parallel plans, so they
aren't completely turned off.
Is there a particular reason why this query can't be parallelized? Or is
there some other way I could structure the query to get it to use
parallelism?
I've tried this both on PG 15.1 (In docker, which seems to be on Debian
15.1) and PG 14.5 (on Centos 7) and got the same results
Thanks,
Alex Kaiser
Full query:
select * from testing where id in
(1608377,5449811,5334677,5458230,2053195,3572313,1949724,3559988,5061560,8479775,6604845,1531946,8578236,1767138,1887562,9224796,801839,1389073,2070024,3378634,5935175,253322,6503217,492190,1646143,6073879,6344884,3120926,6077454,7988246,2359088,2758185,2277417,6144637,7869743,450645,2675170,307844,2752378,9765759,7604173,4702773,9447882,6403407,1020813,2421819,2246889,6118484,5675269,38400,989987,5226654,2910389,9741575,5909526,8752890,1429931,3598345,9541469,6728532,2454806,6470370,6338418,2525642,2286146,9319587,5821710,4138188,8677346,2188096,3242293,9711468,8308979,6505437,5620847,5870305,5177061,7519783,1441852,8264516,7637571,1994901,3979976,8828452,6327321,4377585,608,2620337,9944860,7822890,664424,8832299,8564521,4978015,5910646,8527205,3573524,996558,1270265,7774940,1747145,104339,6867262,9128122,1303267,3810412,2694329,7145818,6719318,3789062,9870348,986684,5603862,1698361,7732472,2816324,1337682,5012390,2309943,1691809,3480539,49005,6857269,913,2599309,2515895,4568931,641192,781186,4762944,13013,4987725,8990541,5654081,193138,4012985,2884209,5352762,9816619,1363209,3019900,8276055,2129378,1121730,7607112,5210575,3288097,1489630,1163497,7136711,9799
Re: Getting an index scan to be a parallel index scan
Rainier,
I tried using the any syntax (had to modify your query slightly) and it
didn't result in any change in the query plan.
postgres=# explain select * from testing where id =
ANY(array[1608377,5449811, ... ...
,4654284,3558460]::integer[]);
QUERY PLAN
--
Gather (cost=0.43..6138.81 rows=1000 width=74)
Workers Planned: 1
Single Copy: true
-> Index Scan using testing_pkey on testing (cost=0.43..6138.81
rows=1000 width=74)
Index Cond: (id = ANY ('{1608377,5449811, ... ... ,4654284,3558460}'::integer[]))
I've never messed around with extended statistics, but I'm not sure how
they would help here. From what I've read they seem to help when your query
is restricting over multiple columns. Since this query is only on one
column I'm not sure what a good "CREATE STATISTICS ..." command to run
would be to improve the query plan. Any suggestions?
David,
As for how I found 'force_parallel_mode', I think I found it first here:
https://postgrespro.com/list/thread-id/2574997 and then I also saw it when
I was searching for 'parallel' on https://postgresqlco.nf .
It's not that I think the parameter would help my query, it was really as a
last resort to try and force the query to be parallel. Without that
parameter, it just does a normal index scan (see the result below). My
thinking with using that parameter was to see if I could force a parallel
query plan just to see if maybe the planner just thought the parallel plan
would be more expensive. So I was surprised to see that even with that
parameter turned on it doesn't actually do anything in parallel. Here is
the plan with that parameter turned off:
postgres=# set force_parallel_mode = off;
SET
postgres=# explain select * from testing where id =
ANY(array[1608377,5449811, ... ...
,4654284,3558460]::integer[]);
QUERY PLAN
Index Scan using testing_pkey on testing (cost=0.43..6138.81 rows=1000
width=74)
Index Cond: (id = ANY ('{1608377,5449811, ... < removed for brevity >
... 4654284,3558460}'::integer[]))
(2 rows)
Thanks,
Alex Kaiser
On Wed, Feb 1, 2023 at 3:30 AM David Rowley wrote:
> On Wed, 1 Feb 2023 at 18:39, Alex Kaiser wrote:
> > postgres=# set force_parallel_mode = on;
>
> There's been a bit of debate about that GUC and I'm wondering how you
> came to the conclusion that it might help you. Can you share details
> of how you found out about it and what made you choose to set it to
> "on"?
>
> David
>
Re: Getting an index scan to be a parallel index scan
Justin,
I did try changing min_parallel_index_scan_size /
min_parallel_table_scan_size and didn't see any change (the below is with
force_parallel_mode = off):
postgres=# set min_parallel_index_scan_size = 0;
SET
postgres=# set min_parallel_table_scan_size = 0;
SET
postgres=# explain select * from testing where id =
ANY(array[1608377,5449811, ... ...
,4654284,3558460]::integer[]);
QUERY PLAN
Index Scan using testing_pkey on testing (cost=0.43..6138.81 rows=1000
width=74)
Index Cond: (id = ANY ('{1608377,5449811, ... < removed for brevity >
... 4654284,3558460}'::integer[]))
(2 rows)
As for 'force_parallel_mode', while this isn't "debugging PG", it isn't
something that I would actually turn on production, just something I was
playing with to see the cost of parallel queries when the planner might not
think they are the most efficient.
Thomas,
Thanks for the explanation. Yes, that is the query plan I was imagining. I
do see how chopping it up could result in an unfair distribution. But my
counter to that would be that wouldn't chopping it up still be better than
not. If things do happen to work out to be fair, now it's X times as fast,
if things are very unfair, then you haven't really lost much (besides the
parallel overhead) compared to the non-parallel query. Or maybe it should
be possible to do the parallel query if there were some statistics (either
normal ones or extended ones) that told the planner that the result would
probably be fair?
Though I do agree that the "work stealing" option would be the most
efficient, but would be a lot more complicated to code up.
I tried out inserting into a separate table, and as you guessed that
worked. For my production scenario that isn't really feasible, but still
cool to see it work.
postgres=# create table ids(
probe_id int PRIMARY KEY
);
insert into ids(probe_id) values (774494);
insert into ids(probe_id) values (9141914);
...
postgres=# select count(*) from ids;
count
---
1000
(1 row)
postgres=# explain select * from testing where id in (select * from ids);
QUERY PLAN
-
Gather (cost=0.43..3504.67 rows=1000 width=74)
Workers Planned: 2
-> Nested Loop (cost=0.43..3504.67 rows=417 width=74)
-> Parallel Seq Scan on ids (cost=0.00..9.17 rows=417 width=4)
-> Index Scan using testing_pkey on testing (cost=0.43..8.37
rows=1 width=74)
Index Cond: (id = ids.probe_id)
(6 rows)
Thanks,
Alex Kaiser
On Wed, Feb 1, 2023 at 1:52 PM Thomas Munro wrote:
> On Wed, Feb 1, 2023 at 6:39 PM Alex Kaiser wrote:
> > select * from testing where id in (1608377,5449811, ... <1000 random
> ids> ,4654284,3558460);
> >
> > Essentially I have a list of 1000 ids and I would like the rows for all
> of those ids.
> >
> > This seems like it would be pretty easy to parallelize, if you have X
> threads then you would split the list of IDs into 1000/X sub lists and give
> one to each thread to go find the rows for ids in the given list. Even
> when I use the following configs I don't get a query plan that actually
> uses any parallelism:
>
> It sounds like the plan you are imagining is something like:
>
> Gather
> Nested Loop Join
> Outer side:
> Inner side: Index scan of your big table
>
> Such a plan would only give the right answer if each process has a
> non-overlapping subset of the constant values to probe the index with,
> and together they have the whole set. Hypothetically, a planner could
> chop that set up beforehand and and give a different subset to each
> process (just as you could do that yourself using N connections and
> separate queries), but that might be unfair: one process might find
> lots of matches, and the others might find none, because of the
> distribution of data. So you'd ideally want some kind of "work
> stealing" scheme, where each worker can take more values to probe from
> whenever it needs more, so that they all keep working until the values
> run out. We don't have a thing that can do that. You might imagine
> that a CTE could do it, so WITH keys_to_look_up AS (VALUES (1), (2),
> ...) SELECT ... JOIN ON ..., but that also doesn't work because we
> don't have a way to do "partial" scans of CTEs either (though someone
> could invent that). Likewise for temporary tables: they are invisible
> to parallel workers, so they can't help us. I have contemplated
> "partial function scans" for set-returning functions, wher
Re: Getting an index scan to be a parallel index scan
Okay after reading http://rhaas.blogspot.com/2018/06/using-forceparallelmode-correctly.html I do see that I was using force_parallel_mode incorectly and wouldn't have gotten what I wanted even if the original query was possible to parallelize. > Maybe, but unfairness multiplies if it's part of a larger plan Ah, I didn't think of that, and it's a good point. > Ok I hacked my copy of PostgreSQL to let me set parallel_setup_costs > to negative numbers ... Thanks for taking the time to do that and look into that. I don't actually think it's worth the confusion to allow this in general, but I was thinking that setting "force_parallel_mode = on" would essentially be doing something equivalent to this (though I now see that is wrong). > But it's probing every index for every one of the values in the big > list, not just the ones that have a non-zero chance of finding a > match, which is a waste of cycles. In my case, this would actually be quite helpful because the real bottleneck when I run this in production is time spent waiting for IO. I was hoping to spread that IO wait time over multiple threads, and wouldn't really care about the few extra wasted CPU cycles. But I can't actually do this as I can't set parallel_setup_costs to be negative, so I wouldn't be able to get PG to choose the parallel plan even if I did partition the table. > If I had more timerons myself ... If only we all had more timerons ... :) Thanks, Alex Kaiser On Wed, Feb 1, 2023 at 6:12 PM David Rowley wrote: > On Thu, 2 Feb 2023 at 14:49, Thomas Munro wrote: > > If I had more timerons myself, I'd like to try to make parallel > > function scans, or parallel CTE scans, work... > > I've not really looked in detail but I thought parallel VALUES scan > might be easier than those two. > > David >
