From 9b17d8bec29ad221a4ea66b4b9a62f9e39f2bf5c Mon Sep 17 00:00:00 2001 From: jbranchaud Date: Tue, 19 Apr 2022 10:41:29 -0500 Subject: [PATCH] Add Inspect Progress Of Long-Running Create Index as a Postgres til --- README.md | 3 +- ...t-progress-of-long-running-create-index.md | 37 +++++++++++++++++++ 2 files changed, 39 insertions(+), 1 deletion(-) create mode 100644 postgres/inspect-progress-of-long-running-create-index.md diff --git a/README.md b/README.md index 9fbe3da..f1cca12 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). -_1192 TILs and counting..._ +_1193 TILs and counting..._ --- @@ -606,6 +606,7 @@ _1192 TILs and counting..._ - [Include All Queries In The Log File](postgres/include-all-queries-in-the-log-file.md) - [Insert A Bunch Of Records With Generate Series](postgres/insert-a-bunch-of-records-with-generate-series.md) - [Insert Just The Defaults](postgres/insert-just-the-defaults.md) +- [Inspect Progress Of Long-Running Create Index](postgres/inspect-progress-of-long-running-create-index.md) - [Install Postgres With uuid-ossp Using asdf](postgres/install-postgres-with-uuid-ossp-using-asdf.md) - [Integers In Postgres](postgres/integers-in-postgres.md) - [Intervals Of Time By Week](postgres/intervals-of-time-by-week.md) diff --git a/postgres/inspect-progress-of-long-running-create-index.md b/postgres/inspect-progress-of-long-running-create-index.md new file mode 100644 index 0000000..4968fb3 --- /dev/null +++ b/postgres/inspect-progress-of-long-running-create-index.md @@ -0,0 +1,37 @@ +# Inspect Progress Of Long-Running Create Index + +Strategically applied indexes are an important part of keeping queries against +a database fast. Initially applying those indexes—especially for large tables +in production—can take a bit of time. + +The `create index` call doesn't provide any indication of progress. So if +applying an index takes minutes or even hours, it can be disconcerting. + +Is it still working or is it locked up? How far along is it? + +Postgres tracks the index creation process in `pg_stat_progress_create_index` +and we can query that table. + +```sql +select + now()::time(0), + a.query, + p.phase, + p.blocks_total, + p.blocks_done, + p.tuples_total, + p.tuples_done, + ai.schemaname, + ai.relname, + ai.indexrelname +from pg_stat_progress_create_index p +join pg_stat_activity a on p.pid = a.pid +left join pg_stat_all_indexes ai on ai.relid = p.relid and ai.indexrelid = p.index_relid; +``` + +There are a bunch of phases that Postgres goes through to create the index, +especially if it is being created `concurrently`. The `blocks_done` and +`tuples_done` numbers will keep ticking along, giving you an indication that +the process is proceeding. + +[source one](https://dba.stackexchange.com/a/249784) and [source two](https://www.depesz.com/2019/04/18/waiting-for-postgresql-12-report-progress-of-create-index-operations/)