|
| 1 | +# Postgres-style syntax for `EXPLAIN` |
| 2 | + |
| 3 | +- Associated: https://github.com/MaterializeInc/database-issues/issues/8889 |
| 4 | + |
| 5 | +## The Problem |
| 6 | + |
| 7 | +`EXPLAIN` is meant to help users understand how Materialize actually |
| 8 | +runs their queries. In the name of streamlining the education process, |
| 9 | +we should make our output as much like Postgres's as is practicable. |
| 10 | + |
| 11 | +Changing `EXPLAIN` is tricky, though: we rely heavily on `EXPLAIN`'s |
| 12 | +completionist output to test our optimizer and debug queries. We must |
| 13 | +be careful to keep these tests while enabling the new behavior. |
| 14 | + |
| 15 | +[#31185](https://github.com/MaterializeInc/materialize/pull/31185) laid |
| 16 | +the groundwork for updating what `AS TEXT` means. So: what should it mean? |
| 17 | + |
| 18 | +## Success Criteria |
| 19 | + |
| 20 | +Our default `EXPLAIN` output should be concise and in a format |
| 21 | +reminiscent of Postgres's. Ideally, `EXPLAIN` output should match the |
| 22 | +output in `mz_lir_mapping`. The documentation should reflect this new |
| 23 | +syntax. |
| 24 | + |
| 25 | +## Out of Scope |
| 26 | + |
| 27 | +We are not going to build new `EXPLAIN` infrastructure, diagrams, |
| 28 | +etc. For example, we are not going to attempt to differentiate between |
| 29 | +the different meanings of `ArrangeBy` in MIR. |
| 30 | + |
| 31 | +We are not going to invent fundamentally new ways of explaining |
| 32 | +how Materialize works. |
| 33 | + |
| 34 | +We are not going to do a user study in advance of any changes. (But we |
| 35 | +will listen attentively to feedback!) |
| 36 | + |
| 37 | +## Solution Proposal |
| 38 | + |
| 39 | +Postgres explain plans have the format: |
| 40 | + |
| 41 | +``` |
| 42 | +Operator |
| 43 | + Detail |
| 44 | + -> Child Operator #1 |
| 45 | + Detail |
| 46 | + ... |
| 47 | + -> Child Operator #2 |
| 48 | + Detail |
| 49 | + ... |
| 50 | +``` |
| 51 | + |
| 52 | +We should aim to follow Postgres's norms: operator names spelled out |
| 53 | +with spaces, and properties are clearly elucidated in human-readable |
| 54 | +formats. When it is sensible, we have simply borrowed Postgres's |
| 55 | +terminology, i.e., `Reduce` is renamed to `GroupAggregate`. |
| 56 | + |
| 57 | +The guiding principle here is that every operator is of the form |
| 58 | +`(Adjective) Operator`, with lines below offering more detail. We |
| 59 | +should choose `Operator` to use familiar and evocative terminology |
| 60 | +(knowing that we can't always follow Postgres, because our execution |
| 61 | +models are so different). We should choose `Adjective` such that |
| 62 | +expensive moments---allocation, arrangement---are called |
| 63 | +out/searchable. |
| 64 | + |
| 65 | +Postgres displays some parts of the query differently from us, namely: |
| 66 | + |
| 67 | + - Column names: |
| 68 | + + When a column name is available, it just gives the name (no number). |
| 69 | + + When a column name is unavailable, it gives the number using `$2`. |
| 70 | + - `Map` and `Project` do not appear |
| 71 | + |
| 72 | +We will use LIR as the new default `EXPLAIN`/`EXPLAIN AS TEXT` |
| 73 | +output. We will update `mz_lir_mapping` to use the new Postgres-style |
| 74 | +syntax (fixing [a bug with `Let` and `LetRec` |
| 75 | +rendering](https://github.com/MaterializeInc/database-issues/issues/8993) |
| 76 | +in the process. |
| 77 | + |
| 78 | +We will need three pieces of work, which should all land together: |
| 79 | + |
| 80 | + - We must implement the new output and put in appropriate SLT tests |
| 81 | + for it. |
| 82 | + - We must update `mz_lir_mapping` to use the new vocabulary. |
| 83 | + - We must update the documentation to explain the new output, ideally |
| 84 | + using this output everywhere `EXPLAIN` is used. |
| 85 | + |
| 86 | +### Concrete Mapping |
| 87 | + |
| 88 | +| LIR node | `mz_lir_mapping` node | New, Postgres-style syntax | |
| 89 | +| :---------- | :--------------------------------------- | :--------------------------------------------------- | |
| 90 | +| `Constant` | `Constant` | `Constant` | |
| 91 | +| `Get` | `Get::PassArrangements l0` | `Index Scan on l0 using ...` or `Stream Scan on l0` | |
| 92 | +| `Get` | `Get::Arrangement l0 (val=...)` | `Index Lookup on l0 using ...` | |
| 93 | +| `Get` | `Get::Arrangement l0` | `Index Scan on l0 using ...` (showing mfp) | |
| 94 | +| `Get` | `Get::Collection l0` | `Read l0` | |
| 95 | +| `Mfp` | `MapFilterProject` | `Map/Filter/Project` | |
| 96 | +| `FlatMap` | `FlatMap` | `Table Function` | |
| 97 | +| `Join` | `Join::Differential` | `Differential Join` | |
| 98 | +| `Join` | `Join::Delta` | `Delta Join` | |
| 99 | +| `Reduce` | `Reduce::Distinct` | `Distinct GroupAggregate` | |
| 100 | +| `Reduce` | `Reduce::Accumulable` | `Accumulable GroupAggregate` | |
| 101 | +| `Reduce` | `Reduce::Hierarchical (monotonic)` | `Monotonic Hierarchical GroupAggregate` | |
| 102 | +| `Reduce` | `Reduce::Hierarchical (buckets: ...)` | `Bucketed Hierarchical GroupAggregate` | |
| 103 | +| `Reduce` | `Reduce::Basic` | `Non-incremental GroupAggregate` | |
| 104 | +| `Reduce` | `Reduce::Collation` | `Collated GroupAggregate` (details?) | |
| 105 | +| `TopK` | `TopK::MonotonicTop1` | `Monotonic Top1` | |
| 106 | +| `TopK` | `TopK::MonotonicTopK` | `Monotonic TopK` | |
| 107 | +| `TopK` | `TopK::Basic` | `Non-monotonic TopK` | |
| 108 | +| `Negate` | `Negate` | `Negate Diffs` | |
| 109 | +| `Threshold` | `Threshold` | `Threshold Diffs` | |
| 110 | +| `Union` | `Union` | `Union` | |
| 111 | +| `Union` | `Union (consolidates output)` | `Consolidating Union` | |
| 112 | +| `ArrangeBy` | `Arrange` | `Arrange` or `Stream/Arrange` | |
| 113 | +| `Let` | `e0 With l1 = e1 ...` | `e1 With l1 = e1 ...` | |
| 114 | +| `LetRec` | `e0 With Mutually Recursive l1 = e1 ...` | `e0 With Mutually Recursve l1 = e1 ...` | |
| 115 | + |
| 116 | +Notice that we have used the following "expensive" adjectives: |
| 117 | +`Non-incremental`, `Bucketed`, `Non-monotonic`, `Consolidating`. |
| 118 | + |
| 119 | +In the new Postgres-style syntax, extra information will appear on the |
| 120 | +next line: for joins, it will be the join pipelines; for |
| 121 | +`Map/Filter/Project` it will be the expressions used in the maps and |
| 122 | +filters. |
| 123 | + |
| 124 | +For `Delta Join` in particular, we will want to push information |
| 125 | +further down in the listing; see [TPC-H query 3](#tpc-h-query-3) below |
| 126 | +for an example. |
| 127 | + |
| 128 | +### Formerly Open Questions |
| 129 | + |
| 130 | +**Should we show `Project`? Should we show _all_ expressions for `Map` |
| 131 | +and `Filter`?** Yes: we will show all Mfp expressions by default. |
| 132 | + |
| 133 | +**How much of this data should `mz_lir_mapping` show?** I propose |
| 134 | +showing the first line plus anything involving scalar expressions |
| 135 | +(e.g., `Map/Filter/Project`s, `Join` equivalences, etc.). |
| 136 | + |
| 137 | +**What about names?** Separate efforts |
| 138 | +([#31802](https://github.com/MaterializeInc/materialize/pull/31802) |
| 139 | +will help us [get more column |
| 140 | +names](https://github.com/MaterializeInc/database-issues/issues/8960)). Showing |
| 141 | +_only_ column names (without numbers) can induce some confusion when |
| 142 | +we have self-joins, as in outer-join lowering. We will want to add |
| 143 | +context (e.g., the table alias, `f1.f_col = f2.f_col`). |
| 144 | + |
| 145 | +## Minimal Viable Prototype |
| 146 | + |
| 147 | +These examples are adapted from existing MIR explain plans, so they |
| 148 | +are not completely faithful to the language above (e.g., `Map` and |
| 149 | +`Filter` are separate, when they will be combined in |
| 150 | +`Map/Filter/Project`). |
| 151 | + |
| 152 | +Arity is included in the Postgres style (cf. "width="), though we will |
| 153 | +hopefully not need it when we have good column names. |
| 154 | + |
| 155 | +### TPC-H query 1 |
| 156 | + |
| 157 | +The query: |
| 158 | + |
| 159 | +```sql |
| 160 | +SELECT |
| 161 | + l_returnflag, |
| 162 | + l_linestatus, |
| 163 | + sum(l_quantity) AS sum_qty, |
| 164 | + sum(l_extendedprice) AS sum_base_price, |
| 165 | + sum(l_extendedprice * (1 - l_discount)) AS sum_disc_price, |
| 166 | + sum(l_extendedprice * (1 - l_discount) * (1 + l_tax)) AS sum_charge, |
| 167 | + avg(l_quantity) AS avg_qty, |
| 168 | + avg(l_extendedprice) AS avg_price, |
| 169 | + avg(l_discount) AS avg_disc, |
| 170 | + count(*) AS count_order |
| 171 | +FROM |
| 172 | + lineitem |
| 173 | +WHERE |
| 174 | + l_shipdate <= DATE '1998-12-01' - INTERVAL '60' day |
| 175 | +GROUP BY |
| 176 | + l_returnflag, |
| 177 | + l_linestatus |
| 178 | +ORDER BY |
| 179 | + l_returnflag, |
| 180 | + l_linestatus; |
| 181 | +``` |
| 182 | + |
| 183 | +Postgres `EXPLAIN`: |
| 184 | + |
| 185 | +``` |
| 186 | + GroupAggregate (cost=14.53..18.89 rows=67 width=248) |
| 187 | + Group Key: l_returnflag, l_linestatus |
| 188 | + -> Sort (cost=14.53..14.70 rows=67 width=88) |
| 189 | + Sort Key: l_returnflag, l_linestatus |
| 190 | + -> Seq Scan on lineitem (cost=0.00..12.50 rows=67 width=88) |
| 191 | + Filter: (l_shipdate <= '1998-10-02 00:00:00'::timestamp without time zone) |
| 192 | +(6 rows) |
| 193 | +``` |
| 194 | + |
| 195 | +Materialize `EXPLAIN`: |
| 196 | + |
| 197 | +``` |
| 198 | + Finish order_by=[#0{l_returnflag} asc nulls_last, #1{l_linestatus} asc nulls_last] output=[#0..=#9] |
| 199 | + Project (#0{l_returnflag}..=#5{sum}, #9..=#11, #6{count}) // { arity: 10 } |
| 200 | + Map (bigint_to_numeric(case when (#6{count} = 0) then null else #6{count} end), (#2{sum_l_quantity} / #8), (#3{sum_l_extendedprice} / #8), (#7{sum_l_discount} / #8)) // { arity: 12 } |
| 201 | + Reduce group_by=[#4{l_returnflag}, #5{l_linestatus}] aggregates=[sum(#0{l_quantity}), sum(#1{l_extendedprice}), sum((#1{l_extendedprice} * (1 - #2{l_discount}))), sum(((#1{l_extendedprice} * (1 - #2{l_discount})) * (1 + #3{l_tax}))), count(*), sum(#2{l_discount})] // { arity: 8 } |
| 202 | + Project (#4{l_quantity}..=#9{l_linestatus}) // { arity: 6 } |
| 203 | + Filter (date_to_timestamp(#10{l_shipdate}) <= 1998-10-02 00:00:00) // { arity: 16 } |
| 204 | + ReadIndex on=lineitem pk_lineitem_orderkey_linenumber=[*** full scan ***] // { arity: 16 } |
| 205 | +
|
| 206 | +Used Indexes: |
| 207 | + - materialize.public.pk_lineitem_orderkey_linenumber (*** full scan ***) |
| 208 | +
|
| 209 | +Target cluster: quickstart |
| 210 | +``` |
| 211 | + |
| 212 | +New Materialize `EXPLAIN`: |
| 213 | + |
| 214 | +``` |
| 215 | + Finish |
| 216 | + Order by: l_returnflag, l_linestatus |
| 217 | + -> Project (columns=10) |
| 218 | + Columns: l_returnflag..=sum, #9..=#11, count |
| 219 | + -> Map (columns=12) |
| 220 | + (bigint_to_numeric(case when (count = 0) then null else count end), (sum_l_quantity / #8), (sum_l_extendedprice / #8), (sum_l_discount / #8)) |
| 221 | + -> Accumulable GroupAggregate (columns=8) |
| 222 | + Group Key: l_returnflag, l_linestatus |
| 223 | + Aggregates: sum(l_quantity), sum(l_extendedprice), sum((l_extendedprice * (1 - l_discount))), sum(((l_extendedprice * (1 - l_discount)) * (1 + l_tax))), count(*), sum(l_discount) |
| 224 | + -> Project (columns=6) |
| 225 | + Columns: l_quantity..=l_linestatus |
| 226 | + -> Filter (columns=16) |
| 227 | + Predicates: date_to_timestamp(l_shipdate) <= 1998-10-02 00:00:00 |
| 228 | + -> Index Scan using pk_lineitem_orderkey_linenumber on lineitem (columns=16) |
| 229 | +
|
| 230 | +Used Indexes: |
| 231 | + - materialize.public.pk_lineitem_orderkey_linenumber (*** full scan ***) |
| 232 | +``` |
| 233 | + |
| 234 | +### TPC-H Query 3 |
| 235 | + |
| 236 | +The query: |
| 237 | + |
| 238 | +```sql |
| 239 | +SELECT |
| 240 | + l_orderkey, |
| 241 | + sum(l_extendedprice * (1 - l_discount)) AS revenue, |
| 242 | + o_orderdate, |
| 243 | + o_shippriority |
| 244 | +FROM |
| 245 | + customer, |
| 246 | + orders, |
| 247 | + lineitem |
| 248 | +WHERE |
| 249 | + c_mktsegment = 'BUILDING' |
| 250 | + AND c_custkey = o_custkey |
| 251 | + AND l_orderkey = o_orderkey |
| 252 | + AND o_orderdate < DATE '1995-03-15' |
| 253 | + AND l_shipdate > DATE '1995-03-15' |
| 254 | +GROUP BY |
| 255 | + l_orderkey, |
| 256 | + o_orderdate, |
| 257 | + o_shippriority |
| 258 | +ORDER BY |
| 259 | + revenue DESC, |
| 260 | + o_orderdate; |
| 261 | +``` |
| 262 | + |
| 263 | +Postgres `EXPLAIN`: |
| 264 | + |
| 265 | +``` |
| 266 | +Sort (cost=20.78..20.79 rows=1 width=44) |
| 267 | + Sort Key: (sum((lineitem.l_extendedprice * ('1'::numeric - lineitem.l_discount)))) DESC, orders.o_orderdate |
| 268 | + -> GroupAggregate (cost=20.74..20.77 rows=1 width=44) |
| 269 | + Group Key: lineitem.l_orderkey, orders.o_orderdate, orders.o_shippriority |
| 270 | + -> Sort (cost=20.74..20.74 rows=1 width=48) |
| 271 | + Sort Key: lineitem.l_orderkey, orders.o_orderdate, orders.o_shippriority |
| 272 | + -> Nested Loop (cost=0.29..20.73 rows=1 width=48) |
| 273 | + -> Nested Loop (cost=0.14..19.93 rows=1 width=12) |
| 274 | + -> Seq Scan on customer (cost=0.00..11.75 rows=1 width=4) |
| 275 | + Filter: (c_mktsegment = 'BUILDING'::bpchar) |
| 276 | + -> Index Scan using fk_orders_custkey on orders (cost=0.14..8.16 rows=1 width=16) |
| 277 | + Index Cond: (o_custkey = customer.c_custkey) |
| 278 | + Filter: (o_orderdate < '1995-03-15'::date) |
| 279 | + -> Index Scan using fk_lineitem_orderkey on lineitem (cost=0.14..0.79 rows=1 width=40) |
| 280 | + Index Cond: (l_orderkey = orders.o_orderkey) |
| 281 | + Filter: (l_shipdate > '1995-03-15'::date) |
| 282 | +(16 rows) |
| 283 | +``` |
| 284 | + |
| 285 | +Materialize `EXPLAIN`: |
| 286 | + |
| 287 | +``` |
| 288 | +Finish order_by=[#1{sum} desc nulls_first, #2{o_orderdate} asc nulls_last] output=[#0..=#3] |
| 289 | + Project (#0{o_orderkey}, #3{sum}, #1{o_orderdate}, #2{o_shippriority}) (columns=4) |
| 290 | + Reduce group_by=[#0{o_orderkey}..=#2{o_shippriority}] aggregates=[sum((#3{l_extendedprice} * (1 - #4{l_discount})))] (columns=4) |
| 291 | + Project (#8{o_orderkey}, #12{o_orderdate}, #15{o_shippriority}, #22{l_extendedprice}, #23{l_discount}) (columns=5) |
| 292 | + Filter (#6{c_mktsegment} = "BUILDING") AND (#12{o_orderdate} < 1995-03-15) AND (#27{l_shipdate} > 1995-03-15) (columns=33) |
| 293 | + Join on=(#0{c_custkey} = #9{o_custkey} AND #8{o_orderkey} = #17{l_orderkey}) type=delta (columns=33) |
| 294 | + implementation |
| 295 | + %0:customer » %1:orders[#1]KAif » %2:lineitem[#0]KAif |
| 296 | + %1:orders » %0:customer[#0]KAef » %2:lineitem[#0]KAif |
| 297 | + %2:lineitem » %1:orders[#0]KAif » %0:customer[#0]KAef |
| 298 | + ArrangeBy keys=[[#0{c_custkey}]] (columns=8) |
| 299 | + ReadIndex on=customer pk_customer_custkey=[delta join 1st input (full scan)] (columns=8) |
| 300 | + ArrangeBy keys=[[#0{o_orderkey}], [#1{o_custkey}]] (columns=9) |
| 301 | + ReadIndex on=orders pk_orders_orderkey=[delta join lookup] fk_orders_custkey=[delta join lookup] (columns=9) |
| 302 | + ArrangeBy keys=[[#0{l_orderkey}]] (columns=16) |
| 303 | + ReadIndex on=lineitem fk_lineitem_orderkey=[delta join lookup] (columns=16) |
| 304 | +
|
| 305 | +Used Indexes: |
| 306 | + - materialize.public.pk_customer_custkey (delta join 1st input (full scan)) |
| 307 | + - materialize.public.pk_orders_orderkey (delta join lookup) |
| 308 | + - materialize.public.fk_orders_custkey (delta join lookup) |
| 309 | + - materialize.public.fk_lineitem_orderkey (delta join lookup) |
| 310 | +
|
| 311 | +Target cluster: quickstart |
| 312 | +``` |
| 313 | + |
| 314 | +New Materialize `EXPLAIN`: |
| 315 | + |
| 316 | +``` |
| 317 | +Finish |
| 318 | + Order by: sum desc, o_orderdate |
| 319 | + -> Project (columns=4) |
| 320 | + Columns: o_orderkey, sum, o_orderdate, o_shippriority |
| 321 | + -> Reduce (columns=4) |
| 322 | + Group key: o_orderkey..=#2o_shippriority |
| 323 | + Aggregates: sum((l_extendedprice * (1 - l_discount))) |
| 324 | + -> Project (columns=5) |
| 325 | + Columns: o_orderkey, o_orderdate, o_shippriority, l_extendedprice, l_discount |
| 326 | + -> Filter (columns=33) |
| 327 | + Predicates: (c_mktsegment = "BUILDING") AND (o_orderdate < 1995-03-15) AND (l_shipdate > 1995-03-15) |
| 328 | + -> Delta Join (columns=33) |
| 329 | + Conditions: c_custkey = o_custkey AND o_orderkey = l_orderkey |
| 330 | + Pipelines: |
| 331 | + %0:customer » %1:orders[#1]KAif » %2:lineitem[#0]KAif |
| 332 | + %1:orders » %0:customer[#0]KAef » %2:lineitem[#0]KAif |
| 333 | + %2:lineitem » %1:orders[#0]KAif » %0:customer[#0]KAef |
| 334 | + -> Index Scan using pk_customer_custkey on customer (columns=8) |
| 335 | + Delta join first input (full scan): pk_customer_custkey |
| 336 | + -> Index Scan using pk_orders_orderkey, fk_orders_custkey on orders (columns=9) |
| 337 | + Delta join lookup: pk_orders_orderkey (%1), fk_orders_custkey (%0, %2) |
| 338 | + -> Index Scan using fk_lineitem_orderkey on lineitem (columns=16) |
| 339 | + Delta join lookup: fk_lineitem_orderkey (%0, %1, %2) |
| 340 | +
|
| 341 | +Used Indexes: |
| 342 | + - materialize.public.pk_customer_custkey (delta join 1st input (full scan)) |
| 343 | + - materialize.public.pk_orders_orderkey (delta join lookup) |
| 344 | + - materialize.public.fk_orders_custkey (delta join lookup) |
| 345 | + - materialize.public.fk_lineitem_orderkey (delta join lookup) |
| 346 | +
|
| 347 | +Target cluster: quickstart |
| 348 | +``` |
| 349 | + |
| 350 | +## Alternatives |
| 351 | + |
| 352 | +Should we more radically reduce the AST? |
| 353 | + |
| 354 | +~~Should we abandon static `EXPLAIN` and encourage `mz_lir_mapping` |
| 355 | +use?~~ No: being able to `EXPLAIN` ahead of time is valuable, and also |
| 356 | +`mz_lir_mapping` forces us to munge strings in SQL. |
| 357 | + |
| 358 | +## Open questions |
0 commit comments