diff --git a/README.md b/README.md index 3283d6e..31216c2 100644 --- a/README.md +++ b/README.md @@ -10,7 +10,7 @@ pairing with smart people at Hashrocket. For a steady stream of TILs, [sign up for my newsletter](https://crafty-builder-6996.ck.page/e169c61186). -_1528 TILs and counting..._ +_1529 TILs and counting..._ --- @@ -828,6 +828,7 @@ _1528 TILs and counting..._ - [Manage Major Versions With Brew And Direnv](postgres/manage-major-versions-with-brew-and-direnv.md) - [Max Identifier Length Is 63 Bytes](postgres/max-identifier-length-is-63-bytes.md) - [Open Heroku Database In Postico From Terminal](postgres/open-heroku-database-in-postico-from-terminal.md) +- [Output Explain Query Plan In Different Formats](postgres/output-explain-query-plan-in-different-formats.md) - [pg Prefix Is Reserved For System Schemas](postgres/pg-prefix-is-reserved-for-system-schemas.md) - [Postgres Does Not Support Unsigned Integers](postgres/postgres-does-not-support-unsigned-integers.md) - [Prepare, Execute, And Deallocate Statements](postgres/prepare-execute-and-deallocate-statements.md) diff --git a/postgres/output-explain-query-plan-in-different-formats.md b/postgres/output-explain-query-plan-in-different-formats.md new file mode 100644 index 0000000..d91088c --- /dev/null +++ b/postgres/output-explain-query-plan-in-different-formats.md @@ -0,0 +1,57 @@ +# Output Explain Query Plan In Different Formats + +The output of an [`explain` (or `explain analyze`) query +plan](https://www.postgresql.org/docs/current/sql-explain.html) for a given +query defaults to a `TEXT` format that is meant to be read by a person. + +```sql +> explain (analyze) select title from books where created_at > now() - '1 year'::interval; + QUERY PLAN +------------------------------------------------------------------------------------------------- + Seq Scan on books (cost=0.00..1.28 rows=5 width=32) (actual time=0.011..0.017 rows=22 loops=1) + Filter: (created_at > (now() - '1 year'::interval)) + Planning Time: 0.052 ms + Execution Time: 0.027 ms +(4 rows) +``` + +If we instead want the query plan in a standardized format that is parseable +and readable by a program, we can specify an alternate format like `JSON`, +`YAML`, or `XML`. + +Here is the same plan with `format json`: + +```sql +> explain (analyze, format json) select title from books where created_at > now() - '1 year'::interval; + QUERY PLAN +---------------------------------------------------------------- + [ + + { + + "Plan": { + + "Node Type": "Seq Scan", + + "Parallel Aware": false, + + "Async Capable": false, + + "Relation Name": "books", + + "Alias": "books", + + "Startup Cost": 0.00, + + "Total Cost": 1.28, + + "Plan Rows": 5, + + "Plan Width": 32, + + "Actual Startup Time": 0.008, + + "Actual Total Time": 0.014, + + "Actual Rows": 22, + + "Actual Loops": 1, + + "Filter": "(created_at > (now() - '1 year'::interval))",+ + "Rows Removed by Filter": 0 + + }, + + "Planning Time": 0.050, + + "Triggers": [ + + ], + + "Execution Time": 0.023 + + } + + ] +(1 row) +``` + +I present all four formats for a complex query plan [in this +Gist](https://gist.github.com/jbranchaud/731b1a68f5cc70c4f7a9e1f5ef570836).