On Tue, 14 May 2024 at 00:41, Dimitrios Apostolou <jimis@xxxxxxx> wrote: > > On Sat, 11 May 2024, David Rowley wrote: > > It will. It's just that Sorting requires fetching everything from its subnode. > > Isn't it plain wrong to have a sort step in the plan than? The different > partitions contain different value ranges with no overlap, and the last > query I posted doesn't even contain an ORDER BY clause, just a DISTINCT > clause on an indexed column. The query does contain an ORDER BY, so if the index is not chosen to provide pre-sorted input, then something has to put the results in the correct order before the LIMIT is applied. > Even with bad estimates, even with seq scan instead of index scan, the > plan should be such that it concludes all parallel work as soon as it > finds the 10 distinct values. And this is actually achieved if I disable > parallel plans. Could it be a bug in the parallel plan generation? If you were to put the n_distinct_inherited estimate back to 200 and disable sort, you should see the costs are higher for the index plan. If that's not the case then there might be a bug. It seems more likely that due to the n_distinct estimate being so low that the planner thought that a large enough fraction of the rows needed to be read and that made the non-index plan appear cheaper. I'd be interested in seeing what the costs are for the index plan. I think the following will give you that (untested): alter table test_runs_raw alter column workitem_n set (n_distinct_inherited=200); analyze test_runs_raw; set enable_sort=0; explain SELECT DISTINCT workitem_n FROM test_runs_raw ORDER BY workitem_n DESC LIMIT 10; -- undo alter table test_runs_raw alter column workitem_n set (n_distinct_inherited=-1); reset enable_sort; David