How can I prevent Postgres from inlining a subquery?
I think OFFSET 0
is the better approach since it's more obviously a hack showing that something weird is going on, and it's unlikely we'll ever change the optimiser behaviour around OFFSET 0
... wheras hopefully CTEs will become inlineable at some point CTEs became inlineable by default in PostgreSQL 12. The following explanation is for completeness's sake; use Seamus's answer.
For uncorrelated subqueries you could exploit PostgreSQL 11 and older's refusal to inline WITH
query terms to rephrase your query as:
WITH t AS (
SELECT * FROM tbl WHERE id IN ('6d48fc431d21', 'd9e659e756ad')
)
SELECT COUNT(*)
FROM t
WHERE data ? 'building_floorspace'
AND data ?| ARRAY['elec_mean_monthly_use', 'gas_mean_monthly_use'];
This has much the same effect as the OFFSET 0
hack, and like the offset 0
hack exploits quirks in Pg's optimizer that people use to get around Pg's lack of query hints ... by using them as query hints.
But the OFFSET 0
hack is somewhat officially blessed, wheras CTE abuse doesn't work anymore in PostgreSQL 12. (Yay!).
Apparently there's a way to tell Postgres not to inline: (0.223ms!)
EXPLAIN ANALYZE SELECT COUNT(*) FROM ( SELECT * FROM tbl WHERE id IN ('6d48fc431d21', 'd9e659e756ad') OFFSET 0 ) AS t WHERE data ? 'building_floorspace' AND data ?| ARRAY['elec_mean_monthly_use', 'gas_mean_monthly_use'];
QUERY PLAN
------------------------------------------------------------------------------------------------------------------------------------------
Aggregate (cost=8.14..8.15 rows=1 width=0) (actual time=0.165..0.166 rows=1 loops=1)
-> Subquery Scan on t (cost=4.14..8.14 rows=1 width=0) (actual time=0.160..0.160 rows=0 loops=1)
Filter: ((t.data ? 'building_floorspace'::text) AND (t.data ?| '{elec_mean_monthly_use,gas_mean_monthly_use}'::text[]))
-> Limit (cost=4.14..8.13 rows=2 width=496) (actual time=0.086..0.092 rows=2 loops=1)
-> Bitmap Heap Scan on tbl (cost=4.14..8.13 rows=2 width=496) (actual time=0.083..0.086 rows=2 loops=1)
Recheck Cond: ((id)::text = ANY ('{6d48fc431d21,d9e659e756ad}'::text[]))
-> Bitmap Index Scan on tbl_pkey (cost=0.00..4.14 rows=2 width=0) (actual time=0.068..0.068 rows=2 loops=1)
Index Cond: ((id)::text = ANY ('{6d48fc431d21,d9e659e756ad}'::text[]))
Total runtime: 0.223 ms
(9 rows)
The trick is OFFSET 0
in the subquery.