Proposal to Enable/Disable Index using ALTER INDEX

Started by Shayon Mukherjeeover 1 year ago137 messages
#1Shayon Mukherjee
shayonj@gmail.com

Hello hackers,

This is my first time posting here, and I’d like to propose a new feature
related to PostgreSQL indexes. If this idea resonates, I’d be happy to
follow up with a patch as well.

*Problem*:
Adding and removing indexes is a common operation in PostgreSQL. On larger
databases, however, these operations can be resource-intensive. When
evaluating the performance impact of one or more indexes, dropping them
might not be ideal since as a user you may want a quicker way to test their
effects without fully committing to removing & adding them back again.
Which can be a time taking operation on larger tables.

*Proposal*:
I propose adding an ALTER INDEX command that allows for enabling or
disabling an index globally. This could look something like:

ALTER INDEX index_name ENABLE;
ALTER INDEX index_name DISABLE;

A disabled index would still receive updates and enforce constraints as
usual but would not be used for queries. This allows users to assess
whether an index impacts query performance before deciding to drop it
entirely.

*Implementation*:
To keep this simple, I suggest toggling the indisvalid flag in pg_index
during the enable/disable operation.

*Additional Considerations*:
- Keeping the index up-to-date while it’s disabled seems preferable, as it
avoids the need to rebuild the index if it’s re-enabled later. The
alternative would be dropping and rebuilding the index upon re-enabling,
which I believe would introduce additional overhead in terms of application
logic & complexity.
- I am also proposing to reuse the existing indisvalid flag to avoid adding
new state and the maintenance that comes with it, but I’m open to feedback
if this approach has potential downsides.
- To keep the scope minimal for now, I propose that we only allow enabling
and disabling indexes globally, and not locally, by supporting it
exclusively in ALTER INDEX. I would love to know if this would break any
SQL grammar promises that I might be unaware of.

I would love to learn if this sounds like a good idea and how it can be
improved further. Accordingly, as a next step I would be very happy to
propose a patch as well.

Best regards,
Shayon Mukherjee

#2David Rowley
dgrowleyml@gmail.com
In reply to: Shayon Mukherjee (#1)
Re: Proposal to Enable/Disable Index using ALTER INDEX

On Tue, 10 Sept 2024 at 09:39, Shayon Mukherjee <shayonj@gmail.com> wrote:

Adding and removing indexes is a common operation in PostgreSQL. On larger databases, however, these operations can be resource-intensive. When evaluating the performance impact of one or more indexes, dropping them might not be ideal since as a user you may want a quicker way to test their effects without fully committing to removing & adding them back again. Which can be a time taking operation on larger tables.

Proposal:
I propose adding an ALTER INDEX command that allows for enabling or disabling an index globally. This could look something like:

ALTER INDEX index_name ENABLE;
ALTER INDEX index_name DISABLE;

A disabled index would still receive updates and enforce constraints as usual but would not be used for queries. This allows users to assess whether an index impacts query performance before deciding to drop it entirely.

I personally think having some way to alter an index to stop it from
being used in query plans would be very useful for the reasons you
mentioned. I don't have any arguments against the syntax you've
proposed. We'd certainly have to clearly document that constraints
are still enforced. Perhaps there is some other syntax which would
self-document slightly better. I just can't think of it right now.

Implementation:
To keep this simple, I suggest toggling the indisvalid flag in pg_index during the enable/disable operation.

That's not a good idea as it would allow ALTER INDEX ... ENABLE; to be
used to make valid a failed concurrently created index. I think this
would need a new flag and everywhere in the planner would need to be
adjusted to ignore indexes when that flag is false.

Additional Considerations:
- Keeping the index up-to-date while it’s disabled seems preferable, as it avoids the need to rebuild the index if it’s re-enabled later. The alternative would be dropping and rebuilding the index upon re-enabling, which I believe would introduce additional overhead in terms of application logic & complexity.

I think the primary use case here is to assist in dropping useless
indexes in a way that can very quickly be undone if the index is more
useful than thought. If you didn't keep the index up-to-date then that
would make the feature useless for that purpose.

If we get the skip scan feature for PG18, then there's likely going to
be lots of people with indexes that they might want to consider
removing after upgrading. Maybe this is a good time to consider this
feature as it possibly won't ever be more useful than it will be after
we get skip scans.

David

#3wenhui qiu
qiuwenhuifx@gmail.com
In reply to: David Rowley (#2)
Re: Proposal to Enable/Disable Index using ALTER INDEX

Hi Shayon
Thank you for your work on this , I think it's great to have this
feature implemented ,I checked the doucment on other databases,It seems
both MySQL 8.0 and oracle supports it, sql server need to rebuild indexes
after disabled,It seems disable the index, it's equivalent to deleting
the index, except that the index's metadata is still retained:
https://docs.oracle.com/cd/E17952_01/mysql-8.0-en/invisible-indexes.html
https://learn.microsoft.com/en-us/sql/t-sql/statements/alter-index-transact-sql?view=sql-server-ver16
https://docs.oracle.com/en/database/oracle/oracle-database/19/sqlrf/ALTER-INDEX.html
->A disabled index would still receive updates and enforce constraints as
usual but would not be used for queries. This allows users to assess ->
->whether an index impacts query performance before deciding to drop it
entirely.
MySQL 8.0 and oracle settings are not visible, index information is always
updated, I would then suggest that the statement be changed to set the
index invisible and visible.

Thanks

David Rowley <dgrowleyml@gmail.com> 于2024年9月10日周二 06:17写道:

Show quoted text

On Tue, 10 Sept 2024 at 09:39, Shayon Mukherjee <shayonj@gmail.com> wrote:

Adding and removing indexes is a common operation in PostgreSQL. On

larger databases, however, these operations can be resource-intensive. When
evaluating the performance impact of one or more indexes, dropping them
might not be ideal since as a user you may want a quicker way to test their
effects without fully committing to removing & adding them back again.
Which can be a time taking operation on larger tables.

Proposal:
I propose adding an ALTER INDEX command that allows for enabling or

disabling an index globally. This could look something like:

ALTER INDEX index_name ENABLE;
ALTER INDEX index_name DISABLE;

A disabled index would still receive updates and enforce constraints as

usual but would not be used for queries. This allows users to assess
whether an index impacts query performance before deciding to drop it
entirely.

I personally think having some way to alter an index to stop it from
being used in query plans would be very useful for the reasons you
mentioned. I don't have any arguments against the syntax you've
proposed. We'd certainly have to clearly document that constraints
are still enforced. Perhaps there is some other syntax which would
self-document slightly better. I just can't think of it right now.

Implementation:
To keep this simple, I suggest toggling the indisvalid flag in pg_index

during the enable/disable operation.

That's not a good idea as it would allow ALTER INDEX ... ENABLE; to be
used to make valid a failed concurrently created index. I think this
would need a new flag and everywhere in the planner would need to be
adjusted to ignore indexes when that flag is false.

Additional Considerations:
- Keeping the index up-to-date while it’s disabled seems preferable, as

it avoids the need to rebuild the index if it’s re-enabled later. The
alternative would be dropping and rebuilding the index upon re-enabling,
which I believe would introduce additional overhead in terms of application
logic & complexity.

I think the primary use case here is to assist in dropping useless
indexes in a way that can very quickly be undone if the index is more
useful than thought. If you didn't keep the index up-to-date then that
would make the feature useless for that purpose.

If we get the skip scan feature for PG18, then there's likely going to
be lots of people with indexes that they might want to consider
removing after upgrading. Maybe this is a good time to consider this
feature as it possibly won't ever be more useful than it will be after
we get skip scans.

David

#4Michael Banck
mbanck@gmx.net
In reply to: David Rowley (#2)
Re: Proposal to Enable/Disable Index using ALTER INDEX

Hi,

On Tue, Sep 10, 2024 at 10:16:34AM +1200, David Rowley wrote:

On Tue, 10 Sept 2024 at 09:39, Shayon Mukherjee <shayonj@gmail.com> wrote:

Adding and removing indexes is a common operation in PostgreSQL. On
larger databases, however, these operations can be
resource-intensive. When evaluating the performance impact of one or
more indexes, dropping them might not be ideal since as a user you
may want a quicker way to test their effects without fully
committing to removing & adding them back again. Which can be a time
taking operation on larger tables.

Proposal:
I propose adding an ALTER INDEX command that allows for enabling or disabling an index globally. This could look something like:

ALTER INDEX index_name ENABLE;
ALTER INDEX index_name DISABLE;

A disabled index would still receive updates and enforce constraints
as usual but would not be used for queries. This allows users to
assess whether an index impacts query performance before deciding to
drop it entirely.

I personally think having some way to alter an index to stop it from
being used in query plans would be very useful for the reasons you
mentioned. I don't have any arguments against the syntax you've
proposed. We'd certainly have to clearly document that constraints
are still enforced. Perhaps there is some other syntax which would
self-document slightly better. I just can't think of it right now.

Implementation:
To keep this simple, I suggest toggling the indisvalid flag in
pg_index during the enable/disable operation.

That's not a good idea as it would allow ALTER INDEX ... ENABLE; to be
used to make valid a failed concurrently created index. I think this
would need a new flag and everywhere in the planner would need to be
adjusted to ignore indexes when that flag is false.

How about the indislive flag instead? I haven't looked at the code, but
from the documentation ("If false, the index is in process of being
dropped, and
should be ignored for all purposes") it sounds like we made be able to
piggy-back on that instead?

Michael

#5David Rowley
dgrowleyml@gmail.com
In reply to: Michael Banck (#4)
Re: Proposal to Enable/Disable Index using ALTER INDEX

On Tue, 10 Sept 2024 at 22:46, Michael Banck <mbanck@gmx.net> wrote:

How about the indislive flag instead? I haven't looked at the code, but
from the documentation ("If false, the index is in process of being
dropped, and
should be ignored for all purposes") it sounds like we made be able to
piggy-back on that instead?

Doing that could cause an UPDATE which would ordinarily not be
eligible for a HOT-update to become a HOT-update. That would cause
issues if the index is enabled again as the index wouldn't have been
updated during the UPDATE.

I don't see the big deal with adding a new flag. There's even a free
padding byte to put this flag in after indisreplident, so we don't
have to worry about using more memory.

David

#6Shayon Mukherjee
shayonj@gmail.com
In reply to: David Rowley (#5)
Re: Proposal to Enable/Disable Index using ALTER INDEX

+1 for the new flag as well, since it'd be nice to be able to
enable/disable indexes without having to worry about the missed updates /
having to rebuild it.
Shayon

On Tue, Sep 10, 2024 at 8:02 AM David Rowley <dgrowleyml@gmail.com> wrote:

On Tue, 10 Sept 2024 at 22:46, Michael Banck <mbanck@gmx.net> wrote:

How about the indislive flag instead? I haven't looked at the code, but
from the documentation ("If false, the index is in process of being
dropped, and
should be ignored for all purposes") it sounds like we made be able to
piggy-back on that instead?

Doing that could cause an UPDATE which would ordinarily not be
eligible for a HOT-update to become a HOT-update. That would cause
issues if the index is enabled again as the index wouldn't have been
updated during the UPDATE.

I don't see the big deal with adding a new flag. There's even a free
padding byte to put this flag in after indisreplident, so we don't
have to worry about using more memory.

David

--
Kind Regards,
Shayon Mukherjee

#7Shayon Mukherjee
shayonj@gmail.com
In reply to: David Rowley (#2)
Re: Proposal to Enable/Disable Index using ALTER INDEX

Hello,

Thank you for the detailed information and feedback David. Comments inline.

P.S Re-sending it to the mailing list, because I accidentally didn't select
reply-all on the last reply.

On Mon, Sep 9, 2024 at 6:16 PM David Rowley <dgrowleyml@gmail.com> wrote:

On Tue, 10 Sept 2024 at 09:39, Shayon Mukherjee <shayonj@gmail.com> wrote:

Adding and removing indexes is a common operation in PostgreSQL. On

larger databases, however, these operations can be resource-intensive. When
evaluating the performance impact of one or more indexes, dropping them
might not be ideal since as a user you may want a quicker way to test their
effects without fully committing to removing & adding them back again.
Which can be a time taking operation on larger tables.

Proposal:
I propose adding an ALTER INDEX command that allows for enabling or

disabling an index globally. This could look something like:

ALTER INDEX index_name ENABLE;
ALTER INDEX index_name DISABLE;

A disabled index would still receive updates and enforce constraints as

usual but would not be used for queries. This allows users to assess
whether an index impacts query performance before deciding to drop it
entirely.

I personally think having some way to alter an index to stop it from
being used in query plans would be very useful for the reasons you
mentioned. I don't have any arguments against the syntax you've
proposed. We'd certainly have to clearly document that constraints
are still enforced. Perhaps there is some other syntax which would
self-document slightly better. I just can't think of it right now.

Thank you and likewise. I was thinking of piggy backing off of VALID / NOT
VALID, but that might have similar issues (if not more confusion) to the
current proposed syntax. Will be sure to update the documentation.

Implementation:
To keep this simple, I suggest toggling the indisvalid flag in pg_index

during the enable/disable operation.

That's not a good idea as it would allow ALTER INDEX ... ENABLE; to be
used to make valid a failed concurrently created index. I think this
would need a new flag and everywhere in the planner would need to be
adjusted to ignore indexes when that flag is false.

That is a great call and I wasn't thinking of the semantics with the
existing usage of concurrently created indexes.

Additional Considerations:
- Keeping the index up-to-date while it’s disabled seems preferable, as

it avoids the need to rebuild the index if it’s re-enabled later. The
alternative would be dropping and rebuilding the index upon re-enabling,
which I believe would introduce additional overhead in terms of application
logic & complexity.

I think the primary use case here is to assist in dropping useless
indexes in a way that can very quickly be undone if the index is more
useful than thought. If you didn't keep the index up-to-date then that
would make the feature useless for that purpose.

+1

If we get the skip scan feature for PG18, then there's likely going to
be lots of people with indexes that they might want to consider
removing after upgrading. Maybe this is a good time to consider this
feature as it possibly won't ever be more useful than it will be after
we get skip scans.

David

Thank you for the feedback again, I will look into the changes required and
accordingly propose a PATCH.

--
Kind Regards,
Shayon Mukherjee

#8Nathan Bossart
nathandbossart@gmail.com
In reply to: David Rowley (#2)
Re: Proposal to Enable/Disable Index using ALTER INDEX

On Tue, Sep 10, 2024 at 10:16:34AM +1200, David Rowley wrote:

I think the primary use case here is to assist in dropping useless
indexes in a way that can very quickly be undone if the index is more
useful than thought. If you didn't keep the index up-to-date then that
would make the feature useless for that purpose.

If we get the skip scan feature for PG18, then there's likely going to
be lots of people with indexes that they might want to consider
removing after upgrading. Maybe this is a good time to consider this
feature as it possibly won't ever be more useful than it will be after
we get skip scans.

+1, this is something I've wanted for some time. There was some past
discussion, too [0]/messages/by-id/flat/ed8c9ed7-bb5d-aaec-065b-ad4893645deb@2ndQuadrant.com.

[0]: /messages/by-id/flat/ed8c9ed7-bb5d-aaec-065b-ad4893645deb@2ndQuadrant.com

--
nathan

#9David Rowley
dgrowleyml@gmail.com
In reply to: Nathan Bossart (#8)
Re: Proposal to Enable/Disable Index using ALTER INDEX

On Wed, 11 Sept 2024 at 03:12, Nathan Bossart <nathandbossart@gmail.com> wrote:

On Tue, Sep 10, 2024 at 10:16:34AM +1200, David Rowley wrote:

If we get the skip scan feature for PG18, then there's likely going to
be lots of people with indexes that they might want to consider
removing after upgrading. Maybe this is a good time to consider this
feature as it possibly won't ever be more useful than it will be after
we get skip scans.

+1, this is something I've wanted for some time. There was some past
discussion, too [0].

[0] /messages/by-id/flat/ed8c9ed7-bb5d-aaec-065b-ad4893645deb@2ndQuadrant.com

Thanks for digging that up. I'd forgotten about that. I see there was
pushback from having this last time, which is now over 6 years ago.
In the meantime, we still have nothing to make this easy for people.

I think the most important point I read in that thread is [1]/messages/by-id/20180618215635.m5vrnxdxhxytvmcm@alap3.anarazel.de. Maybe
what I mentioned in [2]/messages/by-id/CAKJS1f_L7y_BTGESp5Qd6BSRHXP0mj3x9O9C_U27GU478UwpBw@mail.gmail.com is a good workaround.

Additionally, I think there will need to be syntax in CREATE INDEX for
this. Without that pg_get_indexdef() might return SQL that does not
reflect the current state of the index. MySQL seems to use "CREATE
INDEX name ON table (col) [VISIBLE|INVISIBLE]".

David

[1]: /messages/by-id/20180618215635.m5vrnxdxhxytvmcm@alap3.anarazel.de
[2]: /messages/by-id/CAKJS1f_L7y_BTGESp5Qd6BSRHXP0mj3x9O9C_U27GU478UwpBw@mail.gmail.com

#10Shayon Mukherjee
shayonj@gmail.com
In reply to: David Rowley (#9)
1 attachment(s)
[PATCH] Re: Proposal to Enable/Disable Index using ALTER INDEX

Hello,

Thank you for all the feedback and insights. Work was busy, so I didn't get
to follow up earlier.

This patch introduces the ability to enable or disable indexes using ALTER
INDEX
and CREATE INDEX commands.

Original motivation for the problem and proposal for a patch
can be found here[0]/messages/by-id/CANqtF-oXKe0M=0QOih6H+sZRjE2BWAbkW_1+9nMEAMLxUJg5jA@mail.gmail.com

This patch contains the relevant implementation details, new regression
tests and documentation.
It passes all the existing specs and the newly added regression tests. It
compiles, so the
patch can be applied for testing as well.

I have attached the patch in this email, and have also shared it on my
Github fork[1]https://github.com/shayonj/postgres/pull/1. Mostly so
that I can ensure the full CI passes.

*Implementation details:*
- New Grammar:
* ALTER INDEX ... ENABLE/DISABLE
* CREATE INDEX ... DISABLE

- Default state is enabled. Indexes are only disabled when explicitly
instructed via CREATE INDEX ... DISABLE or ALTER INDEX ... DISABLE.

- Primary Key and Unique constraint indexes are always enabled as well. The
ENABLE/DISABLE grammar is not supported for these types of indexes. They
can
be later disabled via ALTER INDEX ... ENABLE/DISABLE.

- ALTER INDEX ... ENABLE/DISABLE performs an in-place update of the
pg_index
catalog to protect against indcheckxmin.

- pg_get_indexdef() support for the new functionality and grammar. This
change is
reflected in \d output for tables and pg_dump. We show the DISABLE syntax
accordingly.

- Updated create_index.sql regression test to cover the new grammar and
verify
that disabled indexes are not used in queries.

- Modified get_index_paths() and build_index_paths() to exclude disabled
indexes from consideration during query planning.

- No changes are made to stop the index from getting rebuilt. This way we
ensure no
data miss or corruption when index is re-enabled.

- TOAST indexes are supported and enabled by default.

- REINDEX CONCURRENTLY is supported as well and the existing state of
pg_index.indisenabled
is carried over accordingly.

- catversion.h is updated with a new CATALOG_VERSION_NO to reflect change
in pg_index
schema.

- See the changes in create_index.sql to get an idea of the grammar and sql
statements.

- See the changes in create_index.out to get an idea of the catalogue
states and EXPLAIN
output to see when an index is getting used or isn't (when disabled).

I am looking forward to any and all feedback on this patch, including but
not limited to
code quality, tests, and fundamental logic.

Thank you for the reviews and feedback.

[0]: /messages/by-id/CANqtF-oXKe0M=0QOih6H+sZRjE2BWAbkW_1+9nMEAMLxUJg5jA@mail.gmail.com
/messages/by-id/CANqtF-oXKe0M=0QOih6H+sZRjE2BWAbkW_1+9nMEAMLxUJg5jA@mail.gmail.com
[1]: https://github.com/shayonj/postgres/pull/1

Best,
Shayon

On Tue, Sep 10, 2024 at 5:35 PM David Rowley <dgrowleyml@gmail.com> wrote:

On Wed, 11 Sept 2024 at 03:12, Nathan Bossart <nathandbossart@gmail.com>
wrote:

On Tue, Sep 10, 2024 at 10:16:34AM +1200, David Rowley wrote:

If we get the skip scan feature for PG18, then there's likely going to
be lots of people with indexes that they might want to consider
removing after upgrading. Maybe this is a good time to consider this
feature as it possibly won't ever be more useful than it will be after
we get skip scans.

+1, this is something I've wanted for some time. There was some past
discussion, too [0].

[0]

/messages/by-id/flat/ed8c9ed7-bb5d-aaec-065b-ad4893645deb@2ndQuadrant.com

Thanks for digging that up. I'd forgotten about that. I see there was
pushback from having this last time, which is now over 6 years ago.
In the meantime, we still have nothing to make this easy for people.

I think the most important point I read in that thread is [1]. Maybe
what I mentioned in [2] is a good workaround.

Additionally, I think there will need to be syntax in CREATE INDEX for
this. Without that pg_get_indexdef() might return SQL that does not
reflect the current state of the index. MySQL seems to use "CREATE
INDEX name ON table (col) [VISIBLE|INVISIBLE]".

David

[1]
/messages/by-id/20180618215635.m5vrnxdxhxytvmcm@alap3.anarazel.de
[2]
/messages/by-id/CAKJS1f_L7y_BTGESp5Qd6BSRHXP0mj3x9O9C_U27GU478UwpBw@mail.gmail.com

--
Kind Regards,
Shayon Mukherjee

Attachments:

0001-Introduce-the-ability-to-enable-disable-indexes.patchapplication/octet-stream; name=0001-Introduce-the-ability-to-enable-disable-indexes.patchDownload
From 24c3439250d99d59650922e623ff23591dd4286e Mon Sep 17 00:00:00 2001
From: Shayon Mukherjee <shayonj@gmail.com>
Date: Sun, 22 Sep 2024 11:59:45 -0400
Subject: [PATCH] Introduce the ability to enable/disable indexes

This patch introduces the ability to enable or disable indexes using ALTER INDEX
and CREATE INDEX commands.

Original motivation for the problem and proposal for a patch
can be found here: https://www.postgresql.org/message-id/CANqtF-oXKe0M%3D0QOih6H%2BsZRjE2BWAbkW_1%2B9nMEAMLxUJg5jA%40mail.gmail.com

This patch passes all the existing specs and the newly added regression tests. The patch
is ready for review and test. It compiles, so the can patch can be applied for testing as well.

Implementation details:

- New Grammar:
  * ALTER INDEX ... ENABLE/DISABLE
  * CREATE INDEX ... DISABLE

- Default state is enabled. Indexes are only disabled when explicitly
  instructed via CREATE INDEX ... DISABLE or ALTER INDEX ... DISABLE.

- Primary Key and Unique constraint indexes are always enabled as well. The
  ENABLE/DISABLE grammar is not supported for these types of indexes. They can
  be later disabled via ALTER INDEX ... ENABLE/DISABLE.

- ALTER INDEX ... ENABLE/DISABLE performs an in-place update of the pg_index
  catalog to protect against indcheckxmin.

- pg_get_indexdef() support the new functionality and grammar. This change is
  reflected in \d output for tables and pg_dump. We show the DISABLE syntax accordingly.

- Updated create_index.sql regression test to cover the new grammar and verify
  that disabled indexes are not used in queries.

- Modified get_index_paths() and build_index_paths() to exclude disabled
  indexes from consideration during query planning.

- No changes are made to stop the index from getting rebuilt. This way ensure no
  data miss or corruption when index is re-nabled.

- TOAST indexes are supported and enabled by default.

- REINDEX CONCURRENTLY is supported as well and existing state of pg_index.indisenabled
  is carried over accordingly.

- catversion.h is updated with a new CATALOG_VERSION_NO to reflect change in pg_index
  schema.

- See the changes in create_index.sql to get an idea of the grammar and sql statements.

- See the changes in create_index.out to get an idea of the catalogue states and EXPLAIN
  output to see when an index is getting used or isn't (when disabled).

I am looking forward to any and all feedback on this patch, including but not limited to
code quality, tests, fundamental logic.
---
 doc/src/sgml/catalogs.sgml                 |  11 +
 doc/src/sgml/ref/alter_index.sgml          |  39 ++++
 doc/src/sgml/ref/create_index.sgml         |  30 +++
 src/backend/bootstrap/bootparse.y          |   2 +
 src/backend/catalog/index.c                |  31 ++-
 src/backend/catalog/toasting.c             |   2 +-
 src/backend/commands/indexcmds.c           |   4 +
 src/backend/commands/tablecmds.c           |  94 +++++++-
 src/backend/optimizer/path/indxpath.c      |  12 +
 src/backend/optimizer/util/plancat.c       |   2 +
 src/backend/parser/gram.y                  |  48 +++-
 src/backend/parser/parse_utilcmd.c         |   3 +
 src/backend/utils/adt/ruleutils.c          |   4 +
 src/backend/utils/cache/relcache.c         |   1 +
 src/include/catalog/catversion.h           |   2 +-
 src/include/catalog/index.h                |   2 +-
 src/include/catalog/pg_index.h             |   1 +
 src/include/nodes/parsenodes.h             |   3 +
 src/include/nodes/pathnodes.h              |   2 +
 src/test/regress/expected/create_index.out | 250 +++++++++++++++++++++
 src/test/regress/sql/create_index.sql      | 140 ++++++++++++
 21 files changed, 672 insertions(+), 11 deletions(-)

diff --git a/doc/src/sgml/catalogs.sgml b/doc/src/sgml/catalogs.sgml
index bfb97865e1..61fbf5beb5 100644
--- a/doc/src/sgml/catalogs.sgml
+++ b/doc/src/sgml/catalogs.sgml
@@ -4590,6 +4590,17 @@ SCRAM-SHA-256$<replaceable>&lt;iteration count&gt;</replaceable>:<replaceable>&l
        partial index.
       </para></entry>
      </row>
+
+     <row>
+      <entry role="catalog_table_entry"><para role="column_definition">
+       <structfield>indisenabled</structfield> <type>bool</type>
+      </para>
+      <para>
+       If true, the index is currently enabled and should be used for queries.
+       If false, the index is disabled and should not be used for queries,
+       but is still maintained when the table is modified. Default is true.
+      </para></entry>
+     </row>
     </tbody>
    </tgroup>
   </table>
diff --git a/doc/src/sgml/ref/alter_index.sgml b/doc/src/sgml/ref/alter_index.sgml
index e26efec064..613d63b747 100644
--- a/doc/src/sgml/ref/alter_index.sgml
+++ b/doc/src/sgml/ref/alter_index.sgml
@@ -31,6 +31,8 @@ ALTER INDEX [ IF EXISTS ] <replaceable class="parameter">name</replaceable> ALTE
     SET STATISTICS <replaceable class="parameter">integer</replaceable>
 ALTER INDEX ALL IN TABLESPACE <replaceable class="parameter">name</replaceable> [ OWNED BY <replaceable class="parameter">role_name</replaceable> [, ... ] ]
     SET TABLESPACE <replaceable class="parameter">new_tablespace</replaceable> [ NOWAIT ]
+ALTER INDEX [ IF EXISTS ] <replaceable class="parameter">name</replaceable> ENABLE
+ALTER INDEX [ IF EXISTS ] <replaceable class="parameter">name</replaceable> DISABLE
 </synopsis>
  </refsynopsisdiv>
 
@@ -158,6 +160,29 @@ ALTER INDEX ALL IN TABLESPACE <replaceable class="parameter">name</replaceable>
     </listitem>
    </varlistentry>
 
+   <varlistentry>
+    <term><literal>ENABLE</literal></term>
+    <listitem>
+     <para>
+      Enable the specified index. The index will be used by the query planner
+      for query optimization. This is the default state for newly created indexes.
+     </para>
+    </listitem>
+   </varlistentry>
+
+   <varlistentry>
+    <term><literal>DISABLE</literal></term>
+    <listitem>
+     <para>
+      Disable the specified index. A disabled index is not used by the query planner
+      for query optimization, but it is still maintained when the underlying table
+      data changes. This can be useful for testing query performance with and without
+      specific indexes, or for temporarily reducing the overhead of index maintenance
+      during bulk data loading operations.
+     </para>
+    </listitem>
+   </varlistentry>
+
   </variablelist>
   </para>
 
@@ -300,6 +325,20 @@ CREATE INDEX coord_idx ON measured (x, y, (z + t));
 ALTER INDEX coord_idx ALTER COLUMN 3 SET STATISTICS 1000;
 </programlisting></para>
 
+  <para>
+   To enable an index:
+<programlisting>
+ALTER INDEX idx_name ENABLE;
+</programlisting>
+  </para>
+
+  <para>
+   To disable an index:
+<programlisting>
+ALTER INDEX idx_name DISABLE;
+</programlisting>
+  </para>
+
  </refsect1>
 
  <refsect1>
diff --git a/doc/src/sgml/ref/create_index.sgml b/doc/src/sgml/ref/create_index.sgml
index 621bc0e253..bc292fe8bb 100644
--- a/doc/src/sgml/ref/create_index.sgml
+++ b/doc/src/sgml/ref/create_index.sgml
@@ -28,6 +28,7 @@ CREATE [ UNIQUE ] INDEX [ CONCURRENTLY ] [ [ IF NOT EXISTS ] <replaceable class=
     [ WITH ( <replaceable class="parameter">storage_parameter</replaceable> [= <replaceable class="parameter">value</replaceable>] [, ... ] ) ]
     [ TABLESPACE <replaceable class="parameter">tablespace_name</replaceable> ]
     [ WHERE <replaceable class="parameter">predicate</replaceable> ]
+    [ DISABLE ]
 </synopsis>
  </refsynopsisdiv>
 
@@ -586,6 +587,20 @@ CREATE [ UNIQUE ] INDEX [ CONCURRENTLY ] [ [ IF NOT EXISTS ] <replaceable class=
     </para>
     </listitem>
    </varlistentry>
+
+    <varlistentry>
+    <term><literal>DISABLE</literal></term>
+    <listitem>
+      <para>
+      Creates the index in a disabled state (default enabled). A disabled index is not used by the
+      query planner for query optimization, but it is still maintained when the
+      underlying table data changes. This can be useful when you want to create
+      an index without immediately impacting query performance, allowing you to
+      enable it later at a more convenient time. The index can be enabled later
+      using <command>ALTER INDEX ... ENABLE</command>.
+      </para>
+    </listitem>
+    </varlistentry>
    </variablelist>
   </refsect2>
 
@@ -701,6 +716,14 @@ Indexes:
     partitioned index is a metadata only operation.
    </para>
 
+  <para>
+   When creating an index with the <literal>DISABLE</literal> option, the index
+   will be created but not used for query planning. This can be useful for
+   preparing an index in advance of its use, or for testing purposes. The index
+   will still be maintained as the table is modified, so it can be enabled
+   later without needing to be rebuilt. By default all new indexes are enabled.
+  </para>
+
   </refsect2>
  </refsect1>
 
@@ -980,6 +1003,13 @@ SELECT * FROM points
 CREATE INDEX CONCURRENTLY sales_quantity_index ON sales_table (quantity);
 </programlisting></para>
 
+  <para>
+   To create an index on the table <literal>test_table</literal> with the default
+   name, but have it initially disabled:
+<programlisting>
+CREATE INDEX ON test_table (col1) DISABLE;
+</programlisting>
+  </para>
  </refsect1>
 
  <refsect1>
diff --git a/src/backend/bootstrap/bootparse.y b/src/backend/bootstrap/bootparse.y
index 73a7592fb7..6023d58490 100644
--- a/src/backend/bootstrap/bootparse.y
+++ b/src/backend/bootstrap/bootparse.y
@@ -302,6 +302,7 @@ Boot_DeclareIndexStmt:
 					stmt->concurrent = false;
 					stmt->if_not_exists = false;
 					stmt->reset_default_tblspc = false;
+					stmt->isenabled = true;
 
 					/* locks and races need not concern us in bootstrap mode */
 					relationId = RangeVarGetRelid(stmt->relation, NoLock,
@@ -355,6 +356,7 @@ Boot_DeclareUniqueIndexStmt:
 					stmt->concurrent = false;
 					stmt->if_not_exists = false;
 					stmt->reset_default_tblspc = false;
+					stmt->isenabled = true;
 
 					/* locks and races need not concern us in bootstrap mode */
 					relationId = RangeVarGetRelid(stmt->relation, NoLock,
diff --git a/src/backend/catalog/index.c b/src/backend/catalog/index.c
index b2b3ecb524..1989cb8ce9 100644
--- a/src/backend/catalog/index.c
+++ b/src/backend/catalog/index.c
@@ -118,7 +118,8 @@ static void UpdateIndexRelation(Oid indexoid, Oid heapoid,
 								bool isexclusion,
 								bool immediate,
 								bool isvalid,
-								bool isready);
+								bool isready,
+								bool isenabled);
 static void index_update_stats(Relation rel,
 							   bool hasindex,
 							   double reltuples);
@@ -569,7 +570,8 @@ UpdateIndexRelation(Oid indexoid,
 					bool isexclusion,
 					bool immediate,
 					bool isvalid,
-					bool isready)
+					bool isready,
+					bool isenabled)
 {
 	int2vector *indkey;
 	oidvector  *indcollation;
@@ -647,6 +649,7 @@ UpdateIndexRelation(Oid indexoid,
 	values[Anum_pg_index_indisready - 1] = BoolGetDatum(isready);
 	values[Anum_pg_index_indislive - 1] = BoolGetDatum(true);
 	values[Anum_pg_index_indisreplident - 1] = BoolGetDatum(false);
+	values[Anum_pg_index_indisenabled - 1] = BoolGetDatum(isenabled);
 	values[Anum_pg_index_indkey - 1] = PointerGetDatum(indkey);
 	values[Anum_pg_index_indcollation - 1] = PointerGetDatum(indcollation);
 	values[Anum_pg_index_indclass - 1] = PointerGetDatum(indclass);
@@ -712,6 +715,8 @@ UpdateIndexRelation(Oid indexoid,
  *			already exists.
  *		INDEX_CREATE_PARTITIONED:
  *			create a partitioned index (table must be partitioned)
+ *		INDEX_CREATE_DISABLED:
+*				create the index as disabled if instructed, defaults to being enabled.
  * constr_flags: flags passed to index_constraint_create
  *		(only if INDEX_CREATE_ADD_CONSTRAINT is set)
  * allow_system_table_mods: allow table to be a system catalog
@@ -757,6 +762,7 @@ index_create(Relation heapRelation,
 	bool		invalid = (flags & INDEX_CREATE_INVALID) != 0;
 	bool		concurrent = (flags & INDEX_CREATE_CONCURRENT) != 0;
 	bool		partitioned = (flags & INDEX_CREATE_PARTITIONED) != 0;
+	bool 		isenabled  = (flags & INDEX_CREATE_ENABLED) != 0;
 	char		relkind;
 	TransactionId relfrozenxid;
 	MultiXactId relminmxid;
@@ -1040,13 +1046,15 @@ index_create(Relation heapRelation,
 	 *	  (Or, could define a rule to maintain the predicate) --Nels, Feb '92
 	 * ----------------
 	 */
+
 	UpdateIndexRelation(indexRelationId, heapRelationId, parentIndexRelid,
 						indexInfo,
 						collationIds, opclassIds, coloptions,
 						isprimary, is_exclusion,
 						(constr_flags & INDEX_CONSTR_CREATE_DEFERRABLE) == 0,
 						!concurrent && !invalid,
-						!concurrent);
+						!concurrent,
+						isenabled);
 
 	/*
 	 * Register relcache invalidation on the indexes' heap relation, to
@@ -1315,6 +1323,8 @@ index_concurrently_create_copy(Relation heapRelation, Oid oldIndexId,
 	List	   *indexColNames = NIL;
 	List	   *indexExprs = NIL;
 	List	   *indexPreds = NIL;
+	Form_pg_index indexForm;
+	bits16 	 createFlags;
 
 	indexRelation = index_open(oldIndexId, RowExclusiveLock);
 
@@ -1342,6 +1352,9 @@ index_concurrently_create_copy(Relation heapRelation, Oid oldIndexId,
 											Anum_pg_index_indoption);
 	indcoloptions = (int2vector *) DatumGetPointer(colOptionDatum);
 
+	/* Get the enabled state of the original index */
+	indexForm = (Form_pg_index) GETSTRUCT(indexTuple);
+
 	/* Fetch reloptions of index if any */
 	classTuple = SearchSysCache1(RELOID, ObjectIdGetDatum(oldIndexId));
 	if (!HeapTupleIsValid(classTuple))
@@ -1433,6 +1446,16 @@ index_concurrently_create_copy(Relation heapRelation, Oid oldIndexId,
 		stattargets[i].isnull = isnull;
 	}
 
+	/*
+	* Determine the create flags for the new index.
+	* We always use SKIP_BUILD and CONCURRENT for concurrent reindexing.
+	* If the original index was enabled, we also set the ENABLED flag
+	* to maintain the same state in the new index.
+	*/
+	createFlags = INDEX_CREATE_SKIP_BUILD | INDEX_CREATE_CONCURRENT;
+	if (indexForm->indisenabled)
+			createFlags |= INDEX_CREATE_ENABLED;
+
 	/*
 	 * Now create the new index.
 	 *
@@ -1456,7 +1479,7 @@ index_concurrently_create_copy(Relation heapRelation, Oid oldIndexId,
 							  indcoloptions->values,
 							  stattargets,
 							  reloptionsDatum,
-							  INDEX_CREATE_SKIP_BUILD | INDEX_CREATE_CONCURRENT,
+							  createFlags,
 							  0,
 							  true, /* allow table to be a system catalog? */
 							  false,	/* is_internal? */
diff --git a/src/backend/catalog/toasting.c b/src/backend/catalog/toasting.c
index 738bc46ae8..ce497eed58 100644
--- a/src/backend/catalog/toasting.c
+++ b/src/backend/catalog/toasting.c
@@ -324,7 +324,7 @@ create_toast_table(Relation rel, Oid toastOid, Oid toastIndexOid,
 				 BTREE_AM_OID,
 				 rel->rd_rel->reltablespace,
 				 collationIds, opclassIds, NULL, coloptions, NULL, (Datum) 0,
-				 INDEX_CREATE_IS_PRIMARY, 0, true, true, NULL);
+				 INDEX_CREATE_IS_PRIMARY | INDEX_CREATE_ENABLED, 0, true, true, NULL);
 
 	table_close(toast_rel, NoLock);
 
diff --git a/src/backend/commands/indexcmds.c b/src/backend/commands/indexcmds.c
index f99c2d2dee..c8bf2c1fd4 100644
--- a/src/backend/commands/indexcmds.c
+++ b/src/backend/commands/indexcmds.c
@@ -1191,6 +1191,10 @@ DefineIndex(Oid tableId,
 		flags |= INDEX_CREATE_PARTITIONED;
 	if (stmt->primary)
 		flags |= INDEX_CREATE_IS_PRIMARY;
+   if (stmt->isenabled)
+       flags |= INDEX_CREATE_ENABLED;
+   else
+       flags &= ~INDEX_CREATE_ENABLED;
 
 	/*
 	 * If the table is partitioned, and recursion was declined but partitions
diff --git a/src/backend/commands/tablecmds.c b/src/backend/commands/tablecmds.c
index 2d703aa22e..19b78f2ec2 100644
--- a/src/backend/commands/tablecmds.c
+++ b/src/backend/commands/tablecmds.c
@@ -664,7 +664,7 @@ static List *GetParentedForeignKeyRefs(Relation partition);
 static void ATDetachCheckNoForeignKeyRefs(Relation partition);
 static char GetAttributeCompression(Oid atttypid, const char *compression);
 static char GetAttributeStorage(Oid atttypid, const char *storagemode);
-
+static void ATExecEnableDisableIndex(Relation rel, bool enable);
 
 /* ----------------------------------------------------------------
  *		DefineRelation
@@ -4546,6 +4546,8 @@ AlterTableGetLockLevel(List *cmds)
 			case AT_SetExpression:
 			case AT_DropExpression:
 			case AT_SetCompression:
+			case AT_EnableIndex:
+			case AT_DisableIndex:
 				cmd_lockmode = AccessExclusiveLock;
 				break;
 
@@ -5123,6 +5125,12 @@ ATPrepCmd(List **wqueue, Relation rel, AlterTableCmd *cmd,
 			/* No command-specific prep needed */
 			pass = AT_PASS_MISC;
 			break;
+		case AT_EnableIndex:
+		case AT_DisableIndex:
+			ATSimplePermissions(cmd->subtype, rel, ATT_INDEX | ATT_PARTITIONED_INDEX);
+			/* No command-specific prep needed */
+			pass = AT_PASS_MISC;
+			break;
 		default:				/* oops */
 			elog(ERROR, "unrecognized alter table type: %d",
 				 (int) cmd->subtype);
@@ -5519,6 +5527,12 @@ ATExecCmd(List **wqueue, AlteredTableInfo *tab,
 		case AT_DetachPartitionFinalize:
 			address = ATExecDetachPartitionFinalize(rel, ((PartitionCmd *) cmd->def)->name);
 			break;
+		case AT_EnableIndex:
+				ATExecEnableDisableIndex(rel, true);
+				break;
+		case AT_DisableIndex:
+				ATExecEnableDisableIndex(rel, false);
+				break;
 		default:				/* oops */
 			elog(ERROR, "unrecognized alter table type: %d",
 				 (int) cmd->subtype);
@@ -6418,6 +6432,8 @@ alter_table_type_to_string(AlterTableType cmdtype)
 			return "DROP COLUMN";
 		case AT_AddIndex:
 		case AT_ReAddIndex:
+		case AT_EnableIndex:
+		case AT_DisableIndex:
 			return NULL;		/* not real grammar */
 		case AT_AddConstraint:
 		case AT_ReAddConstraint:
@@ -20214,3 +20230,79 @@ GetAttributeStorage(Oid atttypid, const char *storagemode)
 
 	return cstorage;
 }
+
+/*
+ * ATExecEnableDisableIndex function handles the execution of enabling or disabling an index.
+ * It performs an in-place update to preserve the pg_index row's xmin.
+ */
+static void
+ATExecEnableDisableIndex(Relation rel, bool enable)
+{
+    Oid         indexOid = RelationGetRelid(rel);
+    Relation    pg_index;
+    HeapTuple   indexTuple;
+    Form_pg_index indexForm;
+    bool        updated = false;
+
+    /* Open pg_index */
+    pg_index = table_open(IndexRelationId, RowExclusiveLock);
+
+    /* Fetch the index's pg_index tuple */
+    indexTuple = SearchSysCache1(INDEXRELID, ObjectIdGetDatum(indexOid));
+    if (!HeapTupleIsValid(indexTuple))
+        elog(ERROR, "cache lookup failed for index %u", indexOid);
+
+    indexForm = (Form_pg_index) GETSTRUCT(indexTuple);
+
+    /* Check if the index's current state differs from the desired state */
+    if (indexForm->indisenabled != enable)
+    {
+			HeapTuple copyTuple;
+
+			/* Create a modifiable copy of the tuple */
+			copyTuple = heap_copytuple(indexTuple);
+			indexForm = (Form_pg_index) GETSTRUCT(copyTuple);
+
+			indexForm->indisenabled = enable;
+
+			/* Perform an in-place update */
+			heap_inplace_update(pg_index, copyTuple);
+
+			/* Free the copy */
+			heap_freetuple(copyTuple);
+
+			updated = true;
+
+			/* Update relcache */
+			CacheInvalidateRelcache(rel);
+
+			/*
+				* Invalidate the relcache for the table, so that after we commit
+				* all sessions will refresh the table's index state before
+				* attempting to use this index.
+				*/
+			CacheInvalidateRelcache(rel);
+
+			ereport(NOTICE,
+							(errmsg("index \"%s\" is now %s",
+											RelationGetRelationName(rel),
+											enable ? "enabled" : "disabled")));
+    }
+    else
+    {
+			ereport(NOTICE,
+							(errmsg("index \"%s\" is already %s",
+											RelationGetRelationName(rel),
+											enable ? "enabled" : "disabled")));
+    }
+
+    /* Clean up */
+    ReleaseSysCache(indexTuple);
+    table_close(pg_index, RowExclusiveLock);
+
+    /* Invoke the object access hook if we updated the index */
+    if (updated)
+    {
+      InvokeObjectPostAlterHook(IndexRelationId, indexOid, 0);
+    }
+}
diff --git a/src/backend/optimizer/path/indxpath.c b/src/backend/optimizer/path/indxpath.c
index c0fcc7d78d..843237dadf 100644
--- a/src/backend/optimizer/path/indxpath.c
+++ b/src/backend/optimizer/path/indxpath.c
@@ -254,6 +254,10 @@ create_index_paths(PlannerInfo *root, RelOptInfo *rel)
 	{
 		IndexOptInfo *index = (IndexOptInfo *) lfirst(lc);
 
+		/* Skip disabled indexes */
+		if (!index->enabled)
+				continue;
+
 		/* Protect limited-size array in IndexClauseSets */
 		Assert(index->nkeycolumns <= INDEX_MAX_KEYS);
 
@@ -715,6 +719,10 @@ get_index_paths(PlannerInfo *root, RelOptInfo *rel,
 	bool		skip_nonnative_saop = false;
 	ListCell   *lc;
 
+	/* Skip disabled indexes */
+	if (!index->enabled)
+			return;
+
 	/*
 	 * Build simple index paths using the clauses.  Allow ScalarArrayOpExpr
 	 * clauses only if the index AM supports them natively.
@@ -823,6 +831,10 @@ build_index_paths(PlannerInfo *root, RelOptInfo *rel,
 
 	Assert(skip_nonnative_saop != NULL || scantype == ST_BITMAPSCAN);
 
+	/* Skip disabled indexes */
+	if (!index->enabled)
+		return NIL;
+
 	/*
 	 * Check that index supports the desired scan type(s)
 	 */
diff --git a/src/backend/optimizer/util/plancat.c b/src/backend/optimizer/util/plancat.c
index b913f91ff0..30dc6353f6 100644
--- a/src/backend/optimizer/util/plancat.c
+++ b/src/backend/optimizer/util/plancat.c
@@ -192,6 +192,7 @@ get_relation_info(PlannerInfo *root, Oid relationObjectId, bool inhparent,
 		}
 	}
 
+
 	/*
 	 * Estimate relation size --- unless it's an inheritance parent, in which
 	 * case the size we want is not the rel's own size but the size of its
@@ -459,6 +460,7 @@ get_relation_info(PlannerInfo *root, Oid relationObjectId, bool inhparent,
 			info->unique = index->indisunique;
 			info->immediate = index->indimmediate;
 			info->hypothetical = false;
+			info->enabled = index->indisenabled;
 
 			/*
 			 * Estimate the index size.  If it's not a partial index, we lock
diff --git a/src/backend/parser/gram.y b/src/backend/parser/gram.y
index ab304ca989..8c0aad255d 100644
--- a/src/backend/parser/gram.y
+++ b/src/backend/parser/gram.y
@@ -333,7 +333,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 %type <ival>	add_drop opt_asc_desc opt_nulls_order
 
 %type <node>	alter_table_cmd alter_type_cmd opt_collate_clause
-	   replica_identity partition_cmd index_partition_cmd
+	   replica_identity partition_cmd index_partition_cmd index_alter_cmd
 %type <list>	alter_table_cmds alter_type_cmds
 %type <list>    alter_identity_column_option_list
 %type <defelt>  alter_identity_column_option
@@ -496,6 +496,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 %type <boolean> opt_unique opt_verbose opt_full
 %type <boolean> opt_freeze opt_analyze opt_default
 %type <defelt>	opt_binary copy_delimiter
+%type <boolean>  opt_index_enabled
 
 %type <boolean> copy_from opt_program
 
@@ -2144,6 +2145,24 @@ AlterTableStmt:
 					n->nowait = $13;
 					$$ = (Node *) n;
 				}
+    | ALTER INDEX qualified_name index_alter_cmd
+        {
+            AlterTableStmt *n = makeNode(AlterTableStmt);
+            n->relation = $3;
+            n->cmds = list_make1($4);
+            n->objtype = OBJECT_INDEX;
+            n->missing_ok = false;
+            $$ = (Node *) n;
+        }
+    | ALTER INDEX IF_P EXISTS qualified_name index_alter_cmd
+        {
+            AlterTableStmt *n = makeNode(AlterTableStmt);
+            n->relation = $5;
+            n->cmds = list_make1($6);
+            n->objtype = OBJECT_INDEX;
+            n->missing_ok = true;
+            $$ = (Node *) n;
+        }
 		|	ALTER INDEX qualified_name alter_table_cmds
 				{
 					AlterTableStmt *n = makeNode(AlterTableStmt);
@@ -2369,6 +2388,21 @@ index_partition_cmd:
 				}
 		;
 
+index_alter_cmd:
+		/* ALTER INDEX <name> ENABLE|DISABLE */
+    ENABLE_P
+        {
+            AlterTableCmd *n = makeNode(AlterTableCmd);
+            n->subtype = AT_EnableIndex;
+            $$ = (Node *) n;
+        }
+    | DISABLE_P
+        {
+            AlterTableCmd *n = makeNode(AlterTableCmd);
+            n->subtype = AT_DisableIndex;
+            $$ = (Node *) n;
+        }
+    ;
 alter_table_cmd:
 			/* ALTER TABLE <name> ADD <coldef> */
 			ADD_P columnDef
@@ -8102,7 +8136,7 @@ defacl_privilege_target:
 
 IndexStmt:	CREATE opt_unique INDEX opt_concurrently opt_single_name
 			ON relation_expr access_method_clause '(' index_params ')'
-			opt_include opt_unique_null_treatment opt_reloptions OptTableSpace where_clause
+			opt_include opt_unique_null_treatment opt_reloptions OptTableSpace where_clause opt_index_enabled
 				{
 					IndexStmt *n = makeNode(IndexStmt);
 
@@ -8117,6 +8151,7 @@ IndexStmt:	CREATE opt_unique INDEX opt_concurrently opt_single_name
 					n->options = $14;
 					n->tableSpace = $15;
 					n->whereClause = $16;
+					n->isenabled = $17;
 					n->excludeOpNames = NIL;
 					n->idxcomment = NULL;
 					n->indexOid = InvalidOid;
@@ -8134,7 +8169,7 @@ IndexStmt:	CREATE opt_unique INDEX opt_concurrently opt_single_name
 				}
 			| CREATE opt_unique INDEX opt_concurrently IF_P NOT EXISTS name
 			ON relation_expr access_method_clause '(' index_params ')'
-			opt_include opt_unique_null_treatment opt_reloptions OptTableSpace where_clause
+			opt_include opt_unique_null_treatment opt_reloptions OptTableSpace where_clause opt_index_enabled
 				{
 					IndexStmt *n = makeNode(IndexStmt);
 
@@ -8149,6 +8184,7 @@ IndexStmt:	CREATE opt_unique INDEX opt_concurrently opt_single_name
 					n->options = $17;
 					n->tableSpace = $18;
 					n->whereClause = $19;
+					n->isenabled = $20;
 					n->excludeOpNames = NIL;
 					n->idxcomment = NULL;
 					n->indexOid = InvalidOid;
@@ -8171,6 +8207,12 @@ opt_unique:
 			| /*EMPTY*/								{ $$ = false; }
 		;
 
+opt_index_enabled:
+    	ENABLE_P                      { $$ = true; }
+    	| DISABLE_P                   { $$ = false; }
+    	| /*EMPTY*/                 	{ $$ = true; }
+		;
+
 access_method_clause:
 			USING name								{ $$ = $2; }
 			| /*EMPTY*/								{ $$ = DEFAULT_INDEX_TYPE; }
diff --git a/src/backend/parser/parse_utilcmd.c b/src/backend/parser/parse_utilcmd.c
index 1e15ce10b4..32554612ed 100644
--- a/src/backend/parser/parse_utilcmd.c
+++ b/src/backend/parser/parse_utilcmd.c
@@ -1588,6 +1588,7 @@ generateClonedIndexStmt(RangeVar *heapRel, Relation source_idx,
 	index->concurrent = false;
 	index->if_not_exists = false;
 	index->reset_default_tblspc = false;
+	index->isenabled = idxrec->indisenabled;
 
 	/*
 	 * We don't try to preserve the name of the source index; instead, just
@@ -2214,6 +2215,8 @@ transformIndexConstraint(Constraint *constraint, CreateStmtContext *cxt)
 	index->concurrent = false;
 	index->if_not_exists = false;
 	index->reset_default_tblspc = constraint->reset_default_tblspc;
+	/* Ensure indexes for constraints are created as enabled by default */
+	index->isenabled = true;
 
 	/*
 	 * If it's ALTER TABLE ADD CONSTRAINT USING INDEX, look up the index and
diff --git a/src/backend/utils/adt/ruleutils.c b/src/backend/utils/adt/ruleutils.c
index 2177d17e27..05b27ca232 100644
--- a/src/backend/utils/adt/ruleutils.c
+++ b/src/backend/utils/adt/ruleutils.c
@@ -1559,6 +1559,10 @@ pg_get_indexdef_worker(Oid indexrelid, int colno,
 			else
 				appendStringInfo(&buf, " WHERE %s", str);
 		}
+
+		/* Add DISABLE clause if the index is disabled */
+		if (!idxrec->indisenabled)
+				appendStringInfoString(&buf, " DISABLE");
 	}
 
 	/* Clean up */
diff --git a/src/backend/utils/cache/relcache.c b/src/backend/utils/cache/relcache.c
index 5b6b7b809c..7cd5902ad7 100644
--- a/src/backend/utils/cache/relcache.c
+++ b/src/backend/utils/cache/relcache.c
@@ -2344,6 +2344,7 @@ RelationReloadIndexInfo(Relation relation)
 		relation->rd_index->indisready = index->indisready;
 		relation->rd_index->indislive = index->indislive;
 		relation->rd_index->indisreplident = index->indisreplident;
+		relation->rd_index->indisenabled = index->indisenabled;
 
 		/* Copy xmin too, as that is needed to make sense of indcheckxmin */
 		HeapTupleHeaderSetXmin(relation->rd_indextuple->t_data,
diff --git a/src/include/catalog/catversion.h b/src/include/catalog/catversion.h
index 10bb26f2e4..a20af83da4 100644
--- a/src/include/catalog/catversion.h
+++ b/src/include/catalog/catversion.h
@@ -57,6 +57,6 @@
  */
 
 /*							yyyymmddN */
-#define CATALOG_VERSION_NO	202409211
+#define CATALOG_VERSION_NO	202409220
 
 #endif
diff --git a/src/include/catalog/index.h b/src/include/catalog/index.h
index 2dea96f47c..8a47cfd174 100644
--- a/src/include/catalog/index.h
+++ b/src/include/catalog/index.h
@@ -65,6 +65,7 @@ extern void index_check_primary_key(Relation heapRel,
 #define	INDEX_CREATE_IF_NOT_EXISTS			(1 << 4)
 #define	INDEX_CREATE_PARTITIONED			(1 << 5)
 #define INDEX_CREATE_INVALID				(1 << 6)
+#define INDEX_CREATE_ENABLED        (1 << 7)
 
 extern Oid	index_create(Relation heapRelation,
 						 const char *indexRelationName,
@@ -175,7 +176,6 @@ extern void RestoreReindexState(const void *reindexstate);
 
 extern void IndexSetParentIndex(Relation partitionIdx, Oid parentOid);
 
-
 /*
  * itemptr_encode - Encode ItemPointer as int64/int8
  *
diff --git a/src/include/catalog/pg_index.h b/src/include/catalog/pg_index.h
index 6c89639a9e..b0c7e5f365 100644
--- a/src/include/catalog/pg_index.h
+++ b/src/include/catalog/pg_index.h
@@ -44,6 +44,7 @@ CATALOG(pg_index,2610,IndexRelationId) BKI_SCHEMA_MACRO
 	bool		indisready;		/* is this index ready for inserts? */
 	bool		indislive;		/* is this index alive at all? */
 	bool		indisreplident; /* is this index the identity for replication? */
+	bool		indisenabled;	/* is this index enabled for use by queries? */
 
 	/* variable-length fields start here, but we allow direct access to indkey */
 	int2vector	indkey BKI_FORCE_NOT_NULL;	/* column numbers of indexed cols,
diff --git a/src/include/nodes/parsenodes.h b/src/include/nodes/parsenodes.h
index e62ce1b753..e5125895b0 100644
--- a/src/include/nodes/parsenodes.h
+++ b/src/include/nodes/parsenodes.h
@@ -2413,6 +2413,8 @@ typedef enum AlterTableType
 	AT_SetIdentity,				/* SET identity column options */
 	AT_DropIdentity,			/* DROP IDENTITY */
 	AT_ReAddStatistics,			/* internal to commands/tablecmds.c */
+	AT_EnableIndex,				/* ENABLE INDEX */
+  AT_DisableIndex,			/* DISABLE INDEX */
 } AlterTableType;
 
 typedef struct ReplicaIdentityStmt
@@ -3378,6 +3380,7 @@ typedef struct IndexStmt
 	bool		if_not_exists;	/* just do nothing if index already exists? */
 	bool		reset_default_tblspc;	/* reset default_tablespace prior to
 										 * executing */
+  bool    isenabled;		/* true if ENABLE (default), false if DISABLE */
 } IndexStmt;
 
 /* ----------------------
diff --git a/src/include/nodes/pathnodes.h b/src/include/nodes/pathnodes.h
index 07e2415398..4096c4b797 100644
--- a/src/include/nodes/pathnodes.h
+++ b/src/include/nodes/pathnodes.h
@@ -1188,6 +1188,8 @@ struct IndexOptInfo
 	bool		immediate;
 	/* true if index doesn't really exist */
 	bool		hypothetical;
+	/* is index enable? */
+  bool		enabled;
 
 	/*
 	 * Remaining fields are copied from the index AM's API struct
diff --git a/src/test/regress/expected/create_index.out b/src/test/regress/expected/create_index.out
index d3358dfc39..57add757aa 100644
--- a/src/test/regress/expected/create_index.out
+++ b/src/test/regress/expected/create_index.out
@@ -2965,6 +2965,256 @@ ERROR:  REINDEX SCHEMA cannot run inside a transaction block
 END;
 -- concurrently
 REINDEX SCHEMA CONCURRENTLY schema_to_reindex;
+-- Test enable/disable functionality for indexes
+-- Setup
+CREATE TABLE enable_disable_test(id int primary key, data text);
+INSERT INTO enable_disable_test SELECT g, 'data ' || g FROM generate_series(1, 1000) g;
+-- CREATE INDEX with ENABLED/DISABLED
+CREATE INDEX enable_disable_idx1 ON enable_disable_test(data) DISABLE;
+CREATE INDEX enable_disable_idx2 ON enable_disable_test(data);
+SELECT indexrelid::regclass, indisvalid, indisready, indislive, indisenabled
+FROM pg_index
+WHERE indrelid = 'enable_disable_test'::regclass
+ORDER BY indexrelid::regclass::text;
+        indexrelid        | indisvalid | indisready | indislive | indisenabled 
+--------------------------+------------+------------+-----------+--------------
+ enable_disable_idx1      | t          | t          | t         | f
+ enable_disable_idx2      | t          | t          | t         | t
+ enable_disable_test_pkey | t          | t          | t         | t
+(3 rows)
+
+-- ALTER INDEX ... ENABLE/DISABLE
+-- Before
+SELECT indexrelid::regclass, indisvalid, indisready, indislive, indisenabled
+FROM pg_index
+WHERE indrelid = 'enable_disable_test'::regclass
+ORDER BY indexrelid::regclass::text;
+        indexrelid        | indisvalid | indisready | indislive | indisenabled 
+--------------------------+------------+------------+-----------+--------------
+ enable_disable_idx1      | t          | t          | t         | f
+ enable_disable_idx2      | t          | t          | t         | t
+ enable_disable_test_pkey | t          | t          | t         | t
+(3 rows)
+
+ALTER INDEX enable_disable_idx2 DISABLE;
+NOTICE:  index "enable_disable_idx2" is now disabled
+-- After
+SELECT indexrelid::regclass, indisvalid, indisready, indislive, indisenabled
+FROM pg_index
+WHERE indrelid = 'enable_disable_test'::regclass
+ORDER BY indexrelid::regclass::text;
+        indexrelid        | indisvalid | indisready | indislive | indisenabled 
+--------------------------+------------+------------+-----------+--------------
+ enable_disable_idx1      | t          | t          | t         | f
+ enable_disable_idx2      | t          | t          | t         | f
+ enable_disable_test_pkey | t          | t          | t         | t
+(3 rows)
+
+-- Enable all indexes
+ALTER INDEX enable_disable_idx2 ENABLE;
+NOTICE:  index "enable_disable_idx2" is now enabled
+ALTER INDEX enable_disable_idx1 ENABLE;
+NOTICE:  index "enable_disable_idx1" is now enabled
+SELECT indexrelid::regclass, indisvalid, indisready, indislive, indisenabled
+FROM pg_index
+WHERE indrelid = 'enable_disable_test'::regclass
+ORDER BY indexrelid::regclass::text;
+        indexrelid        | indisvalid | indisready | indislive | indisenabled 
+--------------------------+------------+------------+-----------+--------------
+ enable_disable_idx1      | t          | t          | t         | t
+ enable_disable_idx2      | t          | t          | t         | t
+ enable_disable_test_pkey | t          | t          | t         | t
+(3 rows)
+
+-- REINDEX TABLE
+REINDEX TABLE enable_disable_test;
+SELECT indexrelid::regclass, indisvalid, indisready, indislive, indisenabled
+FROM pg_index
+WHERE indrelid = 'enable_disable_test'::regclass
+ORDER BY indexrelid::regclass::text;
+        indexrelid        | indisvalid | indisready | indislive | indisenabled 
+--------------------------+------------+------------+-----------+--------------
+ enable_disable_idx1      | t          | t          | t         | t
+ enable_disable_idx2      | t          | t          | t         | t
+ enable_disable_test_pkey | t          | t          | t         | t
+(3 rows)
+
+-- REINDEX INDEX with enable/disable
+ALTER INDEX enable_disable_idx1 DISABLE;
+NOTICE:  index "enable_disable_idx1" is now disabled
+REINDEX INDEX enable_disable_idx1;
+SELECT indexrelid::regclass, indisvalid, indisready, indislive, indisenabled
+FROM pg_index
+WHERE indrelid = 'enable_disable_test'::regclass
+ORDER BY indexrelid::regclass::text;
+        indexrelid        | indisvalid | indisready | indislive | indisenabled 
+--------------------------+------------+------------+-----------+--------------
+ enable_disable_idx1      | t          | t          | t         | f
+ enable_disable_idx2      | t          | t          | t         | t
+ enable_disable_test_pkey | t          | t          | t         | t
+(3 rows)
+
+-- REINDEX INDEX CONCURRENTLY with enable/disable
+ALTER INDEX enable_disable_idx1 ENABLE;
+NOTICE:  index "enable_disable_idx1" is now enabled
+REINDEX INDEX enable_disable_idx1;
+SELECT indexrelid::regclass, indisvalid, indisready, indislive, indisenabled
+FROM pg_index
+WHERE indrelid = 'enable_disable_test'::regclass
+ORDER BY indexrelid::regclass::text;
+        indexrelid        | indisvalid | indisready | indislive | indisenabled 
+--------------------------+------------+------------+-----------+--------------
+ enable_disable_idx1      | t          | t          | t         | t
+ enable_disable_idx2      | t          | t          | t         | t
+ enable_disable_test_pkey | t          | t          | t         | t
+(3 rows)
+
+-- Test ENABLE/DISABLE on TOAST index
+CREATE TABLE toast_test (id int primary key, data text);
+INSERT INTO toast_test SELECT g, repeat('long text ', 1000) FROM generate_series(1, 10) g;
+-- Check initial state of TOAST index
+SELECT indisvalid, indisready, indislive, indisenabled
+FROM pg_index
+WHERE indexrelid = (SELECT indexrelid FROM pg_index WHERE indrelid = (SELECT reltoastrelid FROM pg_class WHERE oid = 'toast_test'::regclass));
+ indisvalid | indisready | indislive | indisenabled 
+------------+------------+-----------+--------------
+ t          | t          | t         | t
+(1 row)
+
+-- Disable TOAST index
+ALTER INDEX pg_toast.pg_toast_16385_index DISABLE;
+ERROR:  relation "pg_toast.pg_toast_16385_index" does not exist
+-- Check state after disabling TOAST index
+SELECT indisvalid, indisready, indislive, indisenabled
+FROM pg_index
+WHERE indexrelid = (SELECT indexrelid FROM pg_index WHERE indrelid = (SELECT reltoastrelid FROM pg_class WHERE oid = 'toast_test'::regclass));
+ indisvalid | indisready | indislive | indisenabled 
+------------+------------+-----------+--------------
+ t          | t          | t         | t
+(1 row)
+
+-- Enable TOAST index
+ALTER INDEX pg_toast.pg_toast_16385_index ENABLE;
+ERROR:  relation "pg_toast.pg_toast_16385_index" does not exist
+-- Check state after enabling TOAST index
+SELECT indisvalid, indisready, indislive, indisenabled
+FROM pg_index
+WHERE indexrelid = (SELECT indexrelid FROM pg_index WHERE indrelid = (SELECT reltoastrelid FROM pg_class WHERE oid = 'toast_test'::regclass));
+ indisvalid | indisready | indislive | indisenabled 
+------------+------------+-----------+--------------
+ t          | t          | t         | t
+(1 row)
+
+-- Test CREATE TABLE with UNIQUE constraint
+CREATE TABLE unique_constraint_test (id int UNIQUE, data text);
+INSERT INTO unique_constraint_test SELECT g, 'data ' || g FROM generate_series(1, 1000) g;
+SELECT indexrelid::regclass, indisvalid, indisready, indislive, indisenabled
+FROM pg_index
+WHERE indrelid = 'unique_constraint_test'::regclass;
+          indexrelid           | indisvalid | indisready | indislive | indisenabled 
+-------------------------------+------------+------------+-----------+--------------
+ unique_constraint_test_id_key | t          | t          | t         | t
+(1 row)
+
+-- Test that the unique constraint index is used
+EXPLAIN (COSTS OFF) SELECT * FROM unique_constraint_test WHERE id = 500;
+                                QUERY PLAN                                
+--------------------------------------------------------------------------
+ Index Scan using unique_constraint_test_id_key on unique_constraint_test
+   Index Cond: (id = 500)
+(2 rows)
+
+EXPLAIN (COSTS OFF) SELECT * FROM unique_constraint_test WHERE id IN (100, 200, 300);
+                         QUERY PLAN                          
+-------------------------------------------------------------
+ Bitmap Heap Scan on unique_constraint_test
+   Recheck Cond: (id = ANY ('{100,200,300}'::integer[]))
+   ->  Bitmap Index Scan on unique_constraint_test_id_key
+         Index Cond: (id = ANY ('{100,200,300}'::integer[]))
+(4 rows)
+
+-- Test CREATE TABLE with INDEX
+CREATE TABLE index_test (id int, data text);
+INSERT INTO index_test SELECT g, 'data ' || g FROM generate_series(1, 1000) g;
+CREATE INDEX ON index_test (data);
+SELECT indexrelid::regclass, indisvalid, indisready, indislive, indisenabled
+FROM pg_index
+WHERE indrelid = 'index_test'::regclass;
+     indexrelid      | indisvalid | indisready | indislive | indisenabled 
+---------------------+------------+------------+-----------+--------------
+ index_test_data_idx | t          | t          | t         | t
+(1 row)
+
+-- Test that the index is used
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE data = 'data 500';
+                   QUERY PLAN                   
+------------------------------------------------
+ Bitmap Heap Scan on index_test
+   Recheck Cond: (data = 'data 500'::text)
+   ->  Bitmap Index Scan on index_test_data_idx
+         Index Cond: (data = 'data 500'::text)
+(4 rows)
+
+-- Test index usage with joins
+CREATE TABLE join_test (id int PRIMARY KEY, ref_id int);
+INSERT INTO join_test SELECT g, g % 100 FROM generate_series(1, 1000) g;
+EXPLAIN (COSTS OFF)
+SELECT jt.id, it.data
+FROM join_test jt
+JOIN index_test it ON jt.ref_id = it.id
+WHERE jt.id BETWEEN 100 AND 200;
+                          QUERY PLAN                           
+---------------------------------------------------------------
+ Hash Join
+   Hash Cond: (it.id = jt.ref_id)
+   ->  Seq Scan on index_test it
+   ->  Hash
+         ->  Bitmap Heap Scan on join_test jt
+               Recheck Cond: ((id >= 100) AND (id <= 200))
+               ->  Bitmap Index Scan on join_test_pkey
+                     Index Cond: ((id >= 100) AND (id <= 200))
+(8 rows)
+
+-- Test index usage with ORDER BY
+EXPLAIN (COSTS OFF)
+SELECT *
+FROM index_test
+ORDER BY data
+LIMIT 10;
+                        QUERY PLAN                        
+----------------------------------------------------------
+ Limit
+   ->  Index Scan using index_test_data_idx on index_test
+(2 rows)
+
+-- Test disabling an index and its effect on query plan
+ALTER INDEX index_test_data_idx DISABLE;
+NOTICE:  index "index_test_data_idx" is now disabled
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE data = 'data 500';
+             QUERY PLAN              
+-------------------------------------
+ Seq Scan on index_test
+   Filter: (data = 'data 500'::text)
+(2 rows)
+
+-- Re-enable the index
+ALTER INDEX index_test_data_idx ENABLE;
+NOTICE:  index "index_test_data_idx" is now enabled
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE data = 'data 500';
+                   QUERY PLAN                   
+------------------------------------------------
+ Bitmap Heap Scan on index_test
+   Recheck Cond: (data = 'data 500'::text)
+   ->  Bitmap Index Scan on index_test_data_idx
+         Index Cond: (data = 'data 500'::text)
+(4 rows)
+
+-- Clean up
+DROP TABLE enable_disable_test;
+DROP TABLE toast_test;
+DROP TABLE unique_constraint_test;
+DROP TABLE join_test;
+DROP TABLE index_test;
 -- Failure for unauthorized user
 CREATE ROLE regress_reindexuser NOLOGIN;
 SET SESSION ROLE regress_reindexuser;
diff --git a/src/test/regress/sql/create_index.sql b/src/test/regress/sql/create_index.sql
index fe162cc7c3..d599717c6f 100644
--- a/src/test/regress/sql/create_index.sql
+++ b/src/test/regress/sql/create_index.sql
@@ -1297,6 +1297,146 @@ END;
 -- concurrently
 REINDEX SCHEMA CONCURRENTLY schema_to_reindex;
 
+-- Test enable/disable functionality for indexes
+
+-- Setup
+CREATE TABLE enable_disable_test(id int primary key, data text);
+INSERT INTO enable_disable_test SELECT g, 'data ' || g FROM generate_series(1, 1000) g;
+
+-- CREATE INDEX with ENABLED/DISABLED
+CREATE INDEX enable_disable_idx1 ON enable_disable_test(data) DISABLE;
+CREATE INDEX enable_disable_idx2 ON enable_disable_test(data);
+SELECT indexrelid::regclass, indisvalid, indisready, indislive, indisenabled
+FROM pg_index
+WHERE indrelid = 'enable_disable_test'::regclass
+ORDER BY indexrelid::regclass::text;
+
+-- ALTER INDEX ... ENABLE/DISABLE
+-- Before
+SELECT indexrelid::regclass, indisvalid, indisready, indislive, indisenabled
+FROM pg_index
+WHERE indrelid = 'enable_disable_test'::regclass
+ORDER BY indexrelid::regclass::text;
+
+ALTER INDEX enable_disable_idx2 DISABLE;
+-- After
+SELECT indexrelid::regclass, indisvalid, indisready, indislive, indisenabled
+FROM pg_index
+WHERE indrelid = 'enable_disable_test'::regclass
+ORDER BY indexrelid::regclass::text;
+
+-- Enable all indexes
+ALTER INDEX enable_disable_idx2 ENABLE;
+ALTER INDEX enable_disable_idx1 ENABLE;
+SELECT indexrelid::regclass, indisvalid, indisready, indislive, indisenabled
+FROM pg_index
+WHERE indrelid = 'enable_disable_test'::regclass
+ORDER BY indexrelid::regclass::text;
+
+-- REINDEX TABLE
+REINDEX TABLE enable_disable_test;
+SELECT indexrelid::regclass, indisvalid, indisready, indislive, indisenabled
+FROM pg_index
+WHERE indrelid = 'enable_disable_test'::regclass
+ORDER BY indexrelid::regclass::text;
+
+-- REINDEX INDEX with enable/disable
+ALTER INDEX enable_disable_idx1 DISABLE;
+REINDEX INDEX enable_disable_idx1;
+SELECT indexrelid::regclass, indisvalid, indisready, indislive, indisenabled
+FROM pg_index
+WHERE indrelid = 'enable_disable_test'::regclass
+ORDER BY indexrelid::regclass::text;
+
+-- REINDEX INDEX CONCURRENTLY with enable/disable
+ALTER INDEX enable_disable_idx1 ENABLE;
+REINDEX INDEX enable_disable_idx1;
+SELECT indexrelid::regclass, indisvalid, indisready, indislive, indisenabled
+FROM pg_index
+WHERE indrelid = 'enable_disable_test'::regclass
+ORDER BY indexrelid::regclass::text;
+
+-- Test ENABLE/DISABLE on TOAST index
+CREATE TABLE toast_test (id int primary key, data text);
+INSERT INTO toast_test SELECT g, repeat('long text ', 1000) FROM generate_series(1, 10) g;
+
+-- Check initial state of TOAST index
+SELECT indisvalid, indisready, indislive, indisenabled
+FROM pg_index
+WHERE indexrelid = (SELECT indexrelid FROM pg_index WHERE indrelid = (SELECT reltoastrelid FROM pg_class WHERE oid = 'toast_test'::regclass));
+
+-- Disable TOAST index
+ALTER INDEX pg_toast.pg_toast_16385_index DISABLE;
+
+-- Check state after disabling TOAST index
+SELECT indisvalid, indisready, indislive, indisenabled
+FROM pg_index
+WHERE indexrelid = (SELECT indexrelid FROM pg_index WHERE indrelid = (SELECT reltoastrelid FROM pg_class WHERE oid = 'toast_test'::regclass));
+
+-- Enable TOAST index
+ALTER INDEX pg_toast.pg_toast_16385_index ENABLE;
+
+-- Check state after enabling TOAST index
+SELECT indisvalid, indisready, indislive, indisenabled
+FROM pg_index
+WHERE indexrelid = (SELECT indexrelid FROM pg_index WHERE indrelid = (SELECT reltoastrelid FROM pg_class WHERE oid = 'toast_test'::regclass));
+
+-- Test CREATE TABLE with UNIQUE constraint
+CREATE TABLE unique_constraint_test (id int UNIQUE, data text);
+INSERT INTO unique_constraint_test SELECT g, 'data ' || g FROM generate_series(1, 1000) g;
+SELECT indexrelid::regclass, indisvalid, indisready, indislive, indisenabled
+FROM pg_index
+WHERE indrelid = 'unique_constraint_test'::regclass;
+
+-- Test that the unique constraint index is used
+EXPLAIN (COSTS OFF) SELECT * FROM unique_constraint_test WHERE id = 500;
+EXPLAIN (COSTS OFF) SELECT * FROM unique_constraint_test WHERE id IN (100, 200, 300);
+
+-- Test CREATE TABLE with INDEX
+CREATE TABLE index_test (id int, data text);
+INSERT INTO index_test SELECT g, 'data ' || g FROM generate_series(1, 1000) g;
+CREATE INDEX ON index_test (data);
+SELECT indexrelid::regclass, indisvalid, indisready, indislive, indisenabled
+FROM pg_index
+WHERE indrelid = 'index_test'::regclass;
+
+-- Test that the index is used
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE data = 'data 500';
+
+-- Test index usage with joins
+CREATE TABLE join_test (id int PRIMARY KEY, ref_id int);
+INSERT INTO join_test SELECT g, g % 100 FROM generate_series(1, 1000) g;
+
+EXPLAIN (COSTS OFF)
+SELECT jt.id, it.data
+FROM join_test jt
+JOIN index_test it ON jt.ref_id = it.id
+WHERE jt.id BETWEEN 100 AND 200;
+
+-- Test index usage with ORDER BY
+EXPLAIN (COSTS OFF)
+SELECT *
+FROM index_test
+ORDER BY data
+LIMIT 10;
+
+-- Test disabling an index and its effect on query plan
+ALTER INDEX index_test_data_idx DISABLE;
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE data = 'data 500';
+
+-- Re-enable the index
+ALTER INDEX index_test_data_idx ENABLE;
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE data = 'data 500';
+
+-- Clean up
+DROP TABLE enable_disable_test;
+DROP TABLE toast_test;
+DROP TABLE unique_constraint_test;
+DROP TABLE join_test;
+DROP TABLE index_test;
+
 -- Failure for unauthorized user
 CREATE ROLE regress_reindexuser NOLOGIN;
 SET SESSION ROLE regress_reindexuser;
-- 
2.37.1 (Apple Git-137.1)

#11Shayon Mukherjee
shayonj@gmail.com
In reply to: Shayon Mukherjee (#10)
1 attachment(s)
Re: [PATCH] Re: Proposal to Enable/Disable Index using ALTER INDEX

Hello,

I realized there were some white spaces in the diff and a compiler warning
error from CI, so I have fixed those and the updated patch with v2 is now
attached.

Shayon

On Sun, Sep 22, 2024 at 1:42 PM Shayon Mukherjee <shayonj@gmail.com> wrote:

Hello,

Thank you for all the feedback and insights. Work was busy, so I didn't
get to follow up earlier.

This patch introduces the ability to enable or disable indexes using ALTER
INDEX
and CREATE INDEX commands.

Original motivation for the problem and proposal for a patch
can be found here[0]

This patch contains the relevant implementation details, new regression
tests and documentation.
It passes all the existing specs and the newly added regression tests. It
compiles, so the
patch can be applied for testing as well.

I have attached the patch in this email, and have also shared it on my
Github fork[1]. Mostly so
that I can ensure the full CI passes.

*Implementation details:*
- New Grammar:
* ALTER INDEX ... ENABLE/DISABLE
* CREATE INDEX ... DISABLE

- Default state is enabled. Indexes are only disabled when explicitly
instructed via CREATE INDEX ... DISABLE or ALTER INDEX ... DISABLE.

- Primary Key and Unique constraint indexes are always enabled as well.
The
ENABLE/DISABLE grammar is not supported for these types of indexes. They
can
be later disabled via ALTER INDEX ... ENABLE/DISABLE.

- ALTER INDEX ... ENABLE/DISABLE performs an in-place update of the
pg_index
catalog to protect against indcheckxmin.

- pg_get_indexdef() support for the new functionality and grammar. This
change is
reflected in \d output for tables and pg_dump. We show the DISABLE
syntax accordingly.

- Updated create_index.sql regression test to cover the new grammar and
verify
that disabled indexes are not used in queries.

- Modified get_index_paths() and build_index_paths() to exclude disabled
indexes from consideration during query planning.

- No changes are made to stop the index from getting rebuilt. This way we
ensure no
data miss or corruption when index is re-enabled.

- TOAST indexes are supported and enabled by default.

- REINDEX CONCURRENTLY is supported as well and the existing state of
pg_index.indisenabled
is carried over accordingly.

- catversion.h is updated with a new CATALOG_VERSION_NO to reflect change
in pg_index
schema.

- See the changes in create_index.sql to get an idea of the grammar and
sql statements.

- See the changes in create_index.out to get an idea of the catalogue
states and EXPLAIN
output to see when an index is getting used or isn't (when disabled).

I am looking forward to any and all feedback on this patch, including but
not limited to
code quality, tests, and fundamental logic.

Thank you for the reviews and feedback.

[0]
/messages/by-id/CANqtF-oXKe0M=0QOih6H+sZRjE2BWAbkW_1+9nMEAMLxUJg5jA@mail.gmail.com
[1] https://github.com/shayonj/postgres/pull/1

Best,
Shayon

On Tue, Sep 10, 2024 at 5:35 PM David Rowley <dgrowleyml@gmail.com> wrote:

On Wed, 11 Sept 2024 at 03:12, Nathan Bossart <nathandbossart@gmail.com>
wrote:

On Tue, Sep 10, 2024 at 10:16:34AM +1200, David Rowley wrote:

If we get the skip scan feature for PG18, then there's likely going to
be lots of people with indexes that they might want to consider
removing after upgrading. Maybe this is a good time to consider this
feature as it possibly won't ever be more useful than it will be after
we get skip scans.

+1, this is something I've wanted for some time. There was some past
discussion, too [0].

[0]

/messages/by-id/flat/ed8c9ed7-bb5d-aaec-065b-ad4893645deb@2ndQuadrant.com

Thanks for digging that up. I'd forgotten about that. I see there was
pushback from having this last time, which is now over 6 years ago.
In the meantime, we still have nothing to make this easy for people.

I think the most important point I read in that thread is [1]. Maybe
what I mentioned in [2] is a good workaround.

Additionally, I think there will need to be syntax in CREATE INDEX for
this. Without that pg_get_indexdef() might return SQL that does not
reflect the current state of the index. MySQL seems to use "CREATE
INDEX name ON table (col) [VISIBLE|INVISIBLE]".

David

[1]
/messages/by-id/20180618215635.m5vrnxdxhxytvmcm@alap3.anarazel.de
[2]
/messages/by-id/CAKJS1f_L7y_BTGESp5Qd6BSRHXP0mj3x9O9C_U27GU478UwpBw@mail.gmail.com

--
Kind Regards,
Shayon Mukherjee

--
Kind Regards,
Shayon Mukherjee

Attachments:

v2-0001-Introduce-the-ability-to-enable-disable-indexes.patchapplication/octet-stream; name=v2-0001-Introduce-the-ability-to-enable-disable-indexes.patchDownload
From 848b143d6ae1817602aa68710e9bcc033c061da9 Mon Sep 17 00:00:00 2001
From: Shayon Mukherjee <shayonj@gmail.com>
Date: Sun, 22 Sep 2024 14:01:45 -0400
Subject: [PATCH v2] Introduce the ability to enable/disable indexes

---
 doc/src/sgml/catalogs.sgml                 |  11 +
 doc/src/sgml/ref/alter_index.sgml          |  39 ++++
 doc/src/sgml/ref/create_index.sgml         |  29 +++
 src/backend/bootstrap/bootparse.y          |   2 +
 src/backend/catalog/index.c                |  31 ++-
 src/backend/catalog/toasting.c             |   2 +-
 src/backend/commands/indexcmds.c           |   4 +
 src/backend/commands/tablecmds.c           |  94 +++++++-
 src/backend/optimizer/path/indxpath.c      |  12 +
 src/backend/optimizer/util/plancat.c       |   2 +
 src/backend/parser/gram.y                  |  48 +++-
 src/backend/parser/parse_utilcmd.c         |   3 +
 src/backend/utils/adt/ruleutils.c          |   4 +
 src/backend/utils/cache/relcache.c         |   1 +
 src/include/catalog/catversion.h           |   2 +-
 src/include/catalog/index.h                |   2 +-
 src/include/catalog/pg_index.h             |   1 +
 src/include/nodes/parsenodes.h             |   3 +
 src/include/nodes/pathnodes.h              |   2 +
 src/test/regress/expected/create_index.out | 250 +++++++++++++++++++++
 src/test/regress/sql/create_index.sql      | 140 ++++++++++++
 21 files changed, 671 insertions(+), 11 deletions(-)

diff --git a/doc/src/sgml/catalogs.sgml b/doc/src/sgml/catalogs.sgml
index bfb97865e1..61fbf5beb5 100644
--- a/doc/src/sgml/catalogs.sgml
+++ b/doc/src/sgml/catalogs.sgml
@@ -4590,6 +4590,17 @@ SCRAM-SHA-256$<replaceable>&lt;iteration count&gt;</replaceable>:<replaceable>&l
        partial index.
       </para></entry>
      </row>
+
+     <row>
+      <entry role="catalog_table_entry"><para role="column_definition">
+       <structfield>indisenabled</structfield> <type>bool</type>
+      </para>
+      <para>
+       If true, the index is currently enabled and should be used for queries.
+       If false, the index is disabled and should not be used for queries,
+       but is still maintained when the table is modified. Default is true.
+      </para></entry>
+     </row>
     </tbody>
    </tgroup>
   </table>
diff --git a/doc/src/sgml/ref/alter_index.sgml b/doc/src/sgml/ref/alter_index.sgml
index e26efec064..613d63b747 100644
--- a/doc/src/sgml/ref/alter_index.sgml
+++ b/doc/src/sgml/ref/alter_index.sgml
@@ -31,6 +31,8 @@ ALTER INDEX [ IF EXISTS ] <replaceable class="parameter">name</replaceable> ALTE
     SET STATISTICS <replaceable class="parameter">integer</replaceable>
 ALTER INDEX ALL IN TABLESPACE <replaceable class="parameter">name</replaceable> [ OWNED BY <replaceable class="parameter">role_name</replaceable> [, ... ] ]
     SET TABLESPACE <replaceable class="parameter">new_tablespace</replaceable> [ NOWAIT ]
+ALTER INDEX [ IF EXISTS ] <replaceable class="parameter">name</replaceable> ENABLE
+ALTER INDEX [ IF EXISTS ] <replaceable class="parameter">name</replaceable> DISABLE
 </synopsis>
  </refsynopsisdiv>
 
@@ -158,6 +160,29 @@ ALTER INDEX ALL IN TABLESPACE <replaceable class="parameter">name</replaceable>
     </listitem>
    </varlistentry>
 
+   <varlistentry>
+    <term><literal>ENABLE</literal></term>
+    <listitem>
+     <para>
+      Enable the specified index. The index will be used by the query planner
+      for query optimization. This is the default state for newly created indexes.
+     </para>
+    </listitem>
+   </varlistentry>
+
+   <varlistentry>
+    <term><literal>DISABLE</literal></term>
+    <listitem>
+     <para>
+      Disable the specified index. A disabled index is not used by the query planner
+      for query optimization, but it is still maintained when the underlying table
+      data changes. This can be useful for testing query performance with and without
+      specific indexes, or for temporarily reducing the overhead of index maintenance
+      during bulk data loading operations.
+     </para>
+    </listitem>
+   </varlistentry>
+
   </variablelist>
   </para>
 
@@ -300,6 +325,20 @@ CREATE INDEX coord_idx ON measured (x, y, (z + t));
 ALTER INDEX coord_idx ALTER COLUMN 3 SET STATISTICS 1000;
 </programlisting></para>
 
+  <para>
+   To enable an index:
+<programlisting>
+ALTER INDEX idx_name ENABLE;
+</programlisting>
+  </para>
+
+  <para>
+   To disable an index:
+<programlisting>
+ALTER INDEX idx_name DISABLE;
+</programlisting>
+  </para>
+
  </refsect1>
 
  <refsect1>
diff --git a/doc/src/sgml/ref/create_index.sgml b/doc/src/sgml/ref/create_index.sgml
index 621bc0e253..f1eebfa250 100644
--- a/doc/src/sgml/ref/create_index.sgml
+++ b/doc/src/sgml/ref/create_index.sgml
@@ -28,6 +28,7 @@ CREATE [ UNIQUE ] INDEX [ CONCURRENTLY ] [ [ IF NOT EXISTS ] <replaceable class=
     [ WITH ( <replaceable class="parameter">storage_parameter</replaceable> [= <replaceable class="parameter">value</replaceable>] [, ... ] ) ]
     [ TABLESPACE <replaceable class="parameter">tablespace_name</replaceable> ]
     [ WHERE <replaceable class="parameter">predicate</replaceable> ]
+    [ DISABLE ]
 </synopsis>
  </refsynopsisdiv>
 
@@ -380,6 +381,19 @@ CREATE [ UNIQUE ] INDEX [ CONCURRENTLY ] [ [ IF NOT EXISTS ] <replaceable class=
       </listitem>
      </varlistentry>
 
+    <varlistentry>
+      <term><literal>DISABLE</literal></term>
+      <listitem>
+       <para>
+        Creates the index in a disabled state (default enabled). A disabled index is not used by the
+        query planner for query optimization, but it is still maintained when the
+        underlying table data changes. This can be useful when you want to create
+        an index without immediately impacting query performance, allowing you to
+        enable it later at a more convenient time. The index can be enabled later
+        using <command>ALTER INDEX ... ENABLE</command>.
+       </para>
+      </listitem>
+     </varlistentry>
     </variablelist>
 
   <refsect2 id="sql-createindex-storage-parameters" xreflabel="Index Storage Parameters">
@@ -701,6 +715,14 @@ Indexes:
     partitioned index is a metadata only operation.
    </para>
 
+  <para>
+   When creating an index with the <literal>DISABLE</literal> option, the index
+   will be created but not used for query planning. This can be useful for
+   preparing an index in advance of its use, or for testing purposes. The index
+   will still be maintained as the table is modified, so it can be enabled
+   later without needing to be rebuilt. By default all new indexes are enabled.
+  </para>
+
   </refsect2>
  </refsect1>
 
@@ -980,6 +1002,13 @@ SELECT * FROM points
 CREATE INDEX CONCURRENTLY sales_quantity_index ON sales_table (quantity);
 </programlisting></para>
 
+  <para>
+   To create an index on the table <literal>test_table</literal> with the default
+   name, but have it initially disabled:
+<programlisting>
+CREATE INDEX ON test_table (col1) DISABLE;
+</programlisting>
+  </para>
  </refsect1>
 
  <refsect1>
diff --git a/src/backend/bootstrap/bootparse.y b/src/backend/bootstrap/bootparse.y
index 73a7592fb7..6023d58490 100644
--- a/src/backend/bootstrap/bootparse.y
+++ b/src/backend/bootstrap/bootparse.y
@@ -302,6 +302,7 @@ Boot_DeclareIndexStmt:
 					stmt->concurrent = false;
 					stmt->if_not_exists = false;
 					stmt->reset_default_tblspc = false;
+					stmt->isenabled = true;
 
 					/* locks and races need not concern us in bootstrap mode */
 					relationId = RangeVarGetRelid(stmt->relation, NoLock,
@@ -355,6 +356,7 @@ Boot_DeclareUniqueIndexStmt:
 					stmt->concurrent = false;
 					stmt->if_not_exists = false;
 					stmt->reset_default_tblspc = false;
+					stmt->isenabled = true;
 
 					/* locks and races need not concern us in bootstrap mode */
 					relationId = RangeVarGetRelid(stmt->relation, NoLock,
diff --git a/src/backend/catalog/index.c b/src/backend/catalog/index.c
index b2b3ecb524..1989cb8ce9 100644
--- a/src/backend/catalog/index.c
+++ b/src/backend/catalog/index.c
@@ -118,7 +118,8 @@ static void UpdateIndexRelation(Oid indexoid, Oid heapoid,
 								bool isexclusion,
 								bool immediate,
 								bool isvalid,
-								bool isready);
+								bool isready,
+								bool isenabled);
 static void index_update_stats(Relation rel,
 							   bool hasindex,
 							   double reltuples);
@@ -569,7 +570,8 @@ UpdateIndexRelation(Oid indexoid,
 					bool isexclusion,
 					bool immediate,
 					bool isvalid,
-					bool isready)
+					bool isready,
+					bool isenabled)
 {
 	int2vector *indkey;
 	oidvector  *indcollation;
@@ -647,6 +649,7 @@ UpdateIndexRelation(Oid indexoid,
 	values[Anum_pg_index_indisready - 1] = BoolGetDatum(isready);
 	values[Anum_pg_index_indislive - 1] = BoolGetDatum(true);
 	values[Anum_pg_index_indisreplident - 1] = BoolGetDatum(false);
+	values[Anum_pg_index_indisenabled - 1] = BoolGetDatum(isenabled);
 	values[Anum_pg_index_indkey - 1] = PointerGetDatum(indkey);
 	values[Anum_pg_index_indcollation - 1] = PointerGetDatum(indcollation);
 	values[Anum_pg_index_indclass - 1] = PointerGetDatum(indclass);
@@ -712,6 +715,8 @@ UpdateIndexRelation(Oid indexoid,
  *			already exists.
  *		INDEX_CREATE_PARTITIONED:
  *			create a partitioned index (table must be partitioned)
+ *		INDEX_CREATE_DISABLED:
+*				create the index as disabled if instructed, defaults to being enabled.
  * constr_flags: flags passed to index_constraint_create
  *		(only if INDEX_CREATE_ADD_CONSTRAINT is set)
  * allow_system_table_mods: allow table to be a system catalog
@@ -757,6 +762,7 @@ index_create(Relation heapRelation,
 	bool		invalid = (flags & INDEX_CREATE_INVALID) != 0;
 	bool		concurrent = (flags & INDEX_CREATE_CONCURRENT) != 0;
 	bool		partitioned = (flags & INDEX_CREATE_PARTITIONED) != 0;
+	bool 		isenabled  = (flags & INDEX_CREATE_ENABLED) != 0;
 	char		relkind;
 	TransactionId relfrozenxid;
 	MultiXactId relminmxid;
@@ -1040,13 +1046,15 @@ index_create(Relation heapRelation,
 	 *	  (Or, could define a rule to maintain the predicate) --Nels, Feb '92
 	 * ----------------
 	 */
+
 	UpdateIndexRelation(indexRelationId, heapRelationId, parentIndexRelid,
 						indexInfo,
 						collationIds, opclassIds, coloptions,
 						isprimary, is_exclusion,
 						(constr_flags & INDEX_CONSTR_CREATE_DEFERRABLE) == 0,
 						!concurrent && !invalid,
-						!concurrent);
+						!concurrent,
+						isenabled);
 
 	/*
 	 * Register relcache invalidation on the indexes' heap relation, to
@@ -1315,6 +1323,8 @@ index_concurrently_create_copy(Relation heapRelation, Oid oldIndexId,
 	List	   *indexColNames = NIL;
 	List	   *indexExprs = NIL;
 	List	   *indexPreds = NIL;
+	Form_pg_index indexForm;
+	bits16 	 createFlags;
 
 	indexRelation = index_open(oldIndexId, RowExclusiveLock);
 
@@ -1342,6 +1352,9 @@ index_concurrently_create_copy(Relation heapRelation, Oid oldIndexId,
 											Anum_pg_index_indoption);
 	indcoloptions = (int2vector *) DatumGetPointer(colOptionDatum);
 
+	/* Get the enabled state of the original index */
+	indexForm = (Form_pg_index) GETSTRUCT(indexTuple);
+
 	/* Fetch reloptions of index if any */
 	classTuple = SearchSysCache1(RELOID, ObjectIdGetDatum(oldIndexId));
 	if (!HeapTupleIsValid(classTuple))
@@ -1433,6 +1446,16 @@ index_concurrently_create_copy(Relation heapRelation, Oid oldIndexId,
 		stattargets[i].isnull = isnull;
 	}
 
+	/*
+	* Determine the create flags for the new index.
+	* We always use SKIP_BUILD and CONCURRENT for concurrent reindexing.
+	* If the original index was enabled, we also set the ENABLED flag
+	* to maintain the same state in the new index.
+	*/
+	createFlags = INDEX_CREATE_SKIP_BUILD | INDEX_CREATE_CONCURRENT;
+	if (indexForm->indisenabled)
+			createFlags |= INDEX_CREATE_ENABLED;
+
 	/*
 	 * Now create the new index.
 	 *
@@ -1456,7 +1479,7 @@ index_concurrently_create_copy(Relation heapRelation, Oid oldIndexId,
 							  indcoloptions->values,
 							  stattargets,
 							  reloptionsDatum,
-							  INDEX_CREATE_SKIP_BUILD | INDEX_CREATE_CONCURRENT,
+							  createFlags,
 							  0,
 							  true, /* allow table to be a system catalog? */
 							  false,	/* is_internal? */
diff --git a/src/backend/catalog/toasting.c b/src/backend/catalog/toasting.c
index 738bc46ae8..ce497eed58 100644
--- a/src/backend/catalog/toasting.c
+++ b/src/backend/catalog/toasting.c
@@ -324,7 +324,7 @@ create_toast_table(Relation rel, Oid toastOid, Oid toastIndexOid,
 				 BTREE_AM_OID,
 				 rel->rd_rel->reltablespace,
 				 collationIds, opclassIds, NULL, coloptions, NULL, (Datum) 0,
-				 INDEX_CREATE_IS_PRIMARY, 0, true, true, NULL);
+				 INDEX_CREATE_IS_PRIMARY | INDEX_CREATE_ENABLED, 0, true, true, NULL);
 
 	table_close(toast_rel, NoLock);
 
diff --git a/src/backend/commands/indexcmds.c b/src/backend/commands/indexcmds.c
index f99c2d2dee..7cd2041300 100644
--- a/src/backend/commands/indexcmds.c
+++ b/src/backend/commands/indexcmds.c
@@ -1191,6 +1191,10 @@ DefineIndex(Oid tableId,
 		flags |= INDEX_CREATE_PARTITIONED;
 	if (stmt->primary)
 		flags |= INDEX_CREATE_IS_PRIMARY;
+   if (stmt->isenabled)
+		flags |= INDEX_CREATE_ENABLED;
+   else
+		flags &= ~INDEX_CREATE_ENABLED;
 
 	/*
 	 * If the table is partitioned, and recursion was declined but partitions
diff --git a/src/backend/commands/tablecmds.c b/src/backend/commands/tablecmds.c
index 2d703aa22e..905a3f58a2 100644
--- a/src/backend/commands/tablecmds.c
+++ b/src/backend/commands/tablecmds.c
@@ -664,7 +664,7 @@ static List *GetParentedForeignKeyRefs(Relation partition);
 static void ATDetachCheckNoForeignKeyRefs(Relation partition);
 static char GetAttributeCompression(Oid atttypid, const char *compression);
 static char GetAttributeStorage(Oid atttypid, const char *storagemode);
-
+static void ATExecEnableDisableIndex(Relation rel, bool enable);
 
 /* ----------------------------------------------------------------
  *		DefineRelation
@@ -4546,6 +4546,8 @@ AlterTableGetLockLevel(List *cmds)
 			case AT_SetExpression:
 			case AT_DropExpression:
 			case AT_SetCompression:
+			case AT_EnableIndex:
+			case AT_DisableIndex:
 				cmd_lockmode = AccessExclusiveLock;
 				break;
 
@@ -5123,6 +5125,12 @@ ATPrepCmd(List **wqueue, Relation rel, AlterTableCmd *cmd,
 			/* No command-specific prep needed */
 			pass = AT_PASS_MISC;
 			break;
+		case AT_EnableIndex:
+		case AT_DisableIndex:
+			ATSimplePermissions(cmd->subtype, rel, ATT_INDEX | ATT_PARTITIONED_INDEX);
+			/* No command-specific prep needed */
+			pass = AT_PASS_MISC;
+			break;
 		default:				/* oops */
 			elog(ERROR, "unrecognized alter table type: %d",
 				 (int) cmd->subtype);
@@ -5519,6 +5527,12 @@ ATExecCmd(List **wqueue, AlteredTableInfo *tab,
 		case AT_DetachPartitionFinalize:
 			address = ATExecDetachPartitionFinalize(rel, ((PartitionCmd *) cmd->def)->name);
 			break;
+		case AT_EnableIndex:
+				ATExecEnableDisableIndex(rel, true);
+				break;
+		case AT_DisableIndex:
+				ATExecEnableDisableIndex(rel, false);
+				break;
 		default:				/* oops */
 			elog(ERROR, "unrecognized alter table type: %d",
 				 (int) cmd->subtype);
@@ -6418,6 +6432,8 @@ alter_table_type_to_string(AlterTableType cmdtype)
 			return "DROP COLUMN";
 		case AT_AddIndex:
 		case AT_ReAddIndex:
+		case AT_EnableIndex:
+		case AT_DisableIndex:
 			return NULL;		/* not real grammar */
 		case AT_AddConstraint:
 		case AT_ReAddConstraint:
@@ -20214,3 +20230,79 @@ GetAttributeStorage(Oid atttypid, const char *storagemode)
 
 	return cstorage;
 }
+
+/*
+ * ATExecEnableDisableIndex function handles the execution of enabling or disabling an index.
+ * It performs an in-place update to preserve the pg_index row's xmin.
+ */
+static void
+ATExecEnableDisableIndex(Relation rel, bool enable)
+{
+		Oid         indexOid = RelationGetRelid(rel);
+		Relation    pg_index;
+		HeapTuple   indexTuple;
+		Form_pg_index indexForm;
+		bool        updated = false;
+
+		/* Open pg_index */
+		pg_index = table_open(IndexRelationId, RowExclusiveLock);
+
+		/* Fetch the index's pg_index tuple */
+		indexTuple = SearchSysCache1(INDEXRELID, ObjectIdGetDatum(indexOid));
+		if (!HeapTupleIsValid(indexTuple))
+			elog(ERROR, "cache lookup failed for index %u", indexOid);
+
+		indexForm = (Form_pg_index) GETSTRUCT(indexTuple);
+
+		/* Check if the index's current state differs from the desired state */
+		if (indexForm->indisenabled != enable)
+		{
+			HeapTuple copyTuple;
+
+			/* Create a modifiable copy of the tuple */
+			copyTuple = heap_copytuple(indexTuple);
+			indexForm = (Form_pg_index) GETSTRUCT(copyTuple);
+
+			indexForm->indisenabled = enable;
+
+			/* Perform an in-place update */
+			heap_inplace_update(pg_index, copyTuple);
+
+			/* Free the copy */
+			heap_freetuple(copyTuple);
+
+			updated = true;
+
+			/* Update relcache */
+			CacheInvalidateRelcache(rel);
+
+			/*
+				* Invalidate the relcache for the table, so that after we commit
+				* all sessions will refresh the table's index state before
+				* attempting to use this index.
+			*/
+			CacheInvalidateRelcache(rel);
+
+			ereport(NOTICE,
+				(errmsg("index \"%s\" is now %s",
+					RelationGetRelationName(rel),
+					enable ? "enabled" : "disabled")));
+		}
+		else
+		{
+			ereport(NOTICE,
+				(errmsg("index \"%s\" is already %s",
+					RelationGetRelationName(rel),
+					enable ? "enabled" : "disabled")));
+		}
+
+		/* Clean up */
+		ReleaseSysCache(indexTuple);
+		table_close(pg_index, RowExclusiveLock);
+
+		/* Invoke the object access hook if we updated the index */
+		if (updated)
+		{
+			InvokeObjectPostAlterHook(IndexRelationId, indexOid, 0);
+		}
+}
diff --git a/src/backend/optimizer/path/indxpath.c b/src/backend/optimizer/path/indxpath.c
index c0fcc7d78d..843237dadf 100644
--- a/src/backend/optimizer/path/indxpath.c
+++ b/src/backend/optimizer/path/indxpath.c
@@ -254,6 +254,10 @@ create_index_paths(PlannerInfo *root, RelOptInfo *rel)
 	{
 		IndexOptInfo *index = (IndexOptInfo *) lfirst(lc);
 
+		/* Skip disabled indexes */
+		if (!index->enabled)
+				continue;
+
 		/* Protect limited-size array in IndexClauseSets */
 		Assert(index->nkeycolumns <= INDEX_MAX_KEYS);
 
@@ -715,6 +719,10 @@ get_index_paths(PlannerInfo *root, RelOptInfo *rel,
 	bool		skip_nonnative_saop = false;
 	ListCell   *lc;
 
+	/* Skip disabled indexes */
+	if (!index->enabled)
+			return;
+
 	/*
 	 * Build simple index paths using the clauses.  Allow ScalarArrayOpExpr
 	 * clauses only if the index AM supports them natively.
@@ -823,6 +831,10 @@ build_index_paths(PlannerInfo *root, RelOptInfo *rel,
 
 	Assert(skip_nonnative_saop != NULL || scantype == ST_BITMAPSCAN);
 
+	/* Skip disabled indexes */
+	if (!index->enabled)
+		return NIL;
+
 	/*
 	 * Check that index supports the desired scan type(s)
 	 */
diff --git a/src/backend/optimizer/util/plancat.c b/src/backend/optimizer/util/plancat.c
index b913f91ff0..30dc6353f6 100644
--- a/src/backend/optimizer/util/plancat.c
+++ b/src/backend/optimizer/util/plancat.c
@@ -192,6 +192,7 @@ get_relation_info(PlannerInfo *root, Oid relationObjectId, bool inhparent,
 		}
 	}
 
+
 	/*
 	 * Estimate relation size --- unless it's an inheritance parent, in which
 	 * case the size we want is not the rel's own size but the size of its
@@ -459,6 +460,7 @@ get_relation_info(PlannerInfo *root, Oid relationObjectId, bool inhparent,
 			info->unique = index->indisunique;
 			info->immediate = index->indimmediate;
 			info->hypothetical = false;
+			info->enabled = index->indisenabled;
 
 			/*
 			 * Estimate the index size.  If it's not a partial index, we lock
diff --git a/src/backend/parser/gram.y b/src/backend/parser/gram.y
index ab304ca989..7e47541541 100644
--- a/src/backend/parser/gram.y
+++ b/src/backend/parser/gram.y
@@ -333,7 +333,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 %type <ival>	add_drop opt_asc_desc opt_nulls_order
 
 %type <node>	alter_table_cmd alter_type_cmd opt_collate_clause
-	   replica_identity partition_cmd index_partition_cmd
+	   replica_identity partition_cmd index_partition_cmd index_alter_cmd
 %type <list>	alter_table_cmds alter_type_cmds
 %type <list>    alter_identity_column_option_list
 %type <defelt>  alter_identity_column_option
@@ -496,6 +496,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 %type <boolean> opt_unique opt_verbose opt_full
 %type <boolean> opt_freeze opt_analyze opt_default
 %type <defelt>	opt_binary copy_delimiter
+%type <boolean>  opt_index_enabled
 
 %type <boolean> copy_from opt_program
 
@@ -2144,6 +2145,24 @@ AlterTableStmt:
 					n->nowait = $13;
 					$$ = (Node *) n;
 				}
+		| ALTER INDEX qualified_name index_alter_cmd
+				{
+					AlterTableStmt *n = makeNode(AlterTableStmt);
+					n->relation = $3;
+					n->cmds = list_make1($4);
+					n->objtype = OBJECT_INDEX;
+					n->missing_ok = false;
+					$$ = (Node *) n;
+				}
+		| ALTER INDEX IF_P EXISTS qualified_name index_alter_cmd
+				{
+					AlterTableStmt *n = makeNode(AlterTableStmt);
+					n->relation = $5;
+					n->cmds = list_make1($6);
+					n->objtype = OBJECT_INDEX;
+					n->missing_ok = true;
+					$$ = (Node *) n;
+				}
 		|	ALTER INDEX qualified_name alter_table_cmds
 				{
 					AlterTableStmt *n = makeNode(AlterTableStmt);
@@ -2369,6 +2388,21 @@ index_partition_cmd:
 				}
 		;
 
+index_alter_cmd:
+		/* ALTER INDEX <name> ENABLE|DISABLE */
+		ENABLE_P
+			{
+				AlterTableCmd *n = makeNode(AlterTableCmd);
+				n->subtype = AT_EnableIndex;
+				$$ = (Node *) n;
+			}
+		| DISABLE_P
+			{
+				AlterTableCmd *n = makeNode(AlterTableCmd);
+				n->subtype = AT_DisableIndex;
+				$$ = (Node *) n;
+			}
+		;
 alter_table_cmd:
 			/* ALTER TABLE <name> ADD <coldef> */
 			ADD_P columnDef
@@ -8102,7 +8136,7 @@ defacl_privilege_target:
 
 IndexStmt:	CREATE opt_unique INDEX opt_concurrently opt_single_name
 			ON relation_expr access_method_clause '(' index_params ')'
-			opt_include opt_unique_null_treatment opt_reloptions OptTableSpace where_clause
+			opt_include opt_unique_null_treatment opt_reloptions OptTableSpace where_clause opt_index_enabled
 				{
 					IndexStmt *n = makeNode(IndexStmt);
 
@@ -8117,6 +8151,7 @@ IndexStmt:	CREATE opt_unique INDEX opt_concurrently opt_single_name
 					n->options = $14;
 					n->tableSpace = $15;
 					n->whereClause = $16;
+					n->isenabled = $17;
 					n->excludeOpNames = NIL;
 					n->idxcomment = NULL;
 					n->indexOid = InvalidOid;
@@ -8134,7 +8169,7 @@ IndexStmt:	CREATE opt_unique INDEX opt_concurrently opt_single_name
 				}
 			| CREATE opt_unique INDEX opt_concurrently IF_P NOT EXISTS name
 			ON relation_expr access_method_clause '(' index_params ')'
-			opt_include opt_unique_null_treatment opt_reloptions OptTableSpace where_clause
+			opt_include opt_unique_null_treatment opt_reloptions OptTableSpace where_clause opt_index_enabled
 				{
 					IndexStmt *n = makeNode(IndexStmt);
 
@@ -8149,6 +8184,7 @@ IndexStmt:	CREATE opt_unique INDEX opt_concurrently opt_single_name
 					n->options = $17;
 					n->tableSpace = $18;
 					n->whereClause = $19;
+					n->isenabled = $20;
 					n->excludeOpNames = NIL;
 					n->idxcomment = NULL;
 					n->indexOid = InvalidOid;
@@ -8171,6 +8207,12 @@ opt_unique:
 			| /*EMPTY*/								{ $$ = false; }
 		;
 
+opt_index_enabled:
+			ENABLE_P                      { $$ = true; }
+			| DISABLE_P                   { $$ = false; }
+			| /*EMPTY*/                 	{ $$ = true; }
+		;
+
 access_method_clause:
 			USING name								{ $$ = $2; }
 			| /*EMPTY*/								{ $$ = DEFAULT_INDEX_TYPE; }
diff --git a/src/backend/parser/parse_utilcmd.c b/src/backend/parser/parse_utilcmd.c
index 1e15ce10b4..32554612ed 100644
--- a/src/backend/parser/parse_utilcmd.c
+++ b/src/backend/parser/parse_utilcmd.c
@@ -1588,6 +1588,7 @@ generateClonedIndexStmt(RangeVar *heapRel, Relation source_idx,
 	index->concurrent = false;
 	index->if_not_exists = false;
 	index->reset_default_tblspc = false;
+	index->isenabled = idxrec->indisenabled;
 
 	/*
 	 * We don't try to preserve the name of the source index; instead, just
@@ -2214,6 +2215,8 @@ transformIndexConstraint(Constraint *constraint, CreateStmtContext *cxt)
 	index->concurrent = false;
 	index->if_not_exists = false;
 	index->reset_default_tblspc = constraint->reset_default_tblspc;
+	/* Ensure indexes for constraints are created as enabled by default */
+	index->isenabled = true;
 
 	/*
 	 * If it's ALTER TABLE ADD CONSTRAINT USING INDEX, look up the index and
diff --git a/src/backend/utils/adt/ruleutils.c b/src/backend/utils/adt/ruleutils.c
index 2177d17e27..05b27ca232 100644
--- a/src/backend/utils/adt/ruleutils.c
+++ b/src/backend/utils/adt/ruleutils.c
@@ -1559,6 +1559,10 @@ pg_get_indexdef_worker(Oid indexrelid, int colno,
 			else
 				appendStringInfo(&buf, " WHERE %s", str);
 		}
+
+		/* Add DISABLE clause if the index is disabled */
+		if (!idxrec->indisenabled)
+				appendStringInfoString(&buf, " DISABLE");
 	}
 
 	/* Clean up */
diff --git a/src/backend/utils/cache/relcache.c b/src/backend/utils/cache/relcache.c
index 5b6b7b809c..7cd5902ad7 100644
--- a/src/backend/utils/cache/relcache.c
+++ b/src/backend/utils/cache/relcache.c
@@ -2344,6 +2344,7 @@ RelationReloadIndexInfo(Relation relation)
 		relation->rd_index->indisready = index->indisready;
 		relation->rd_index->indislive = index->indislive;
 		relation->rd_index->indisreplident = index->indisreplident;
+		relation->rd_index->indisenabled = index->indisenabled;
 
 		/* Copy xmin too, as that is needed to make sense of indcheckxmin */
 		HeapTupleHeaderSetXmin(relation->rd_indextuple->t_data,
diff --git a/src/include/catalog/catversion.h b/src/include/catalog/catversion.h
index 10bb26f2e4..a20af83da4 100644
--- a/src/include/catalog/catversion.h
+++ b/src/include/catalog/catversion.h
@@ -57,6 +57,6 @@
  */
 
 /*							yyyymmddN */
-#define CATALOG_VERSION_NO	202409211
+#define CATALOG_VERSION_NO	202409220
 
 #endif
diff --git a/src/include/catalog/index.h b/src/include/catalog/index.h
index 2dea96f47c..8a47cfd174 100644
--- a/src/include/catalog/index.h
+++ b/src/include/catalog/index.h
@@ -65,6 +65,7 @@ extern void index_check_primary_key(Relation heapRel,
 #define	INDEX_CREATE_IF_NOT_EXISTS			(1 << 4)
 #define	INDEX_CREATE_PARTITIONED			(1 << 5)
 #define INDEX_CREATE_INVALID				(1 << 6)
+#define INDEX_CREATE_ENABLED        (1 << 7)
 
 extern Oid	index_create(Relation heapRelation,
 						 const char *indexRelationName,
@@ -175,7 +176,6 @@ extern void RestoreReindexState(const void *reindexstate);
 
 extern void IndexSetParentIndex(Relation partitionIdx, Oid parentOid);
 
-
 /*
  * itemptr_encode - Encode ItemPointer as int64/int8
  *
diff --git a/src/include/catalog/pg_index.h b/src/include/catalog/pg_index.h
index 6c89639a9e..b0c7e5f365 100644
--- a/src/include/catalog/pg_index.h
+++ b/src/include/catalog/pg_index.h
@@ -44,6 +44,7 @@ CATALOG(pg_index,2610,IndexRelationId) BKI_SCHEMA_MACRO
 	bool		indisready;		/* is this index ready for inserts? */
 	bool		indislive;		/* is this index alive at all? */
 	bool		indisreplident; /* is this index the identity for replication? */
+	bool		indisenabled;	/* is this index enabled for use by queries? */
 
 	/* variable-length fields start here, but we allow direct access to indkey */
 	int2vector	indkey BKI_FORCE_NOT_NULL;	/* column numbers of indexed cols,
diff --git a/src/include/nodes/parsenodes.h b/src/include/nodes/parsenodes.h
index e62ce1b753..e5125895b0 100644
--- a/src/include/nodes/parsenodes.h
+++ b/src/include/nodes/parsenodes.h
@@ -2413,6 +2413,8 @@ typedef enum AlterTableType
 	AT_SetIdentity,				/* SET identity column options */
 	AT_DropIdentity,			/* DROP IDENTITY */
 	AT_ReAddStatistics,			/* internal to commands/tablecmds.c */
+	AT_EnableIndex,				/* ENABLE INDEX */
+  AT_DisableIndex,			/* DISABLE INDEX */
 } AlterTableType;
 
 typedef struct ReplicaIdentityStmt
@@ -3378,6 +3380,7 @@ typedef struct IndexStmt
 	bool		if_not_exists;	/* just do nothing if index already exists? */
 	bool		reset_default_tblspc;	/* reset default_tablespace prior to
 										 * executing */
+  bool    isenabled;		/* true if ENABLE (default), false if DISABLE */
 } IndexStmt;
 
 /* ----------------------
diff --git a/src/include/nodes/pathnodes.h b/src/include/nodes/pathnodes.h
index 07e2415398..4096c4b797 100644
--- a/src/include/nodes/pathnodes.h
+++ b/src/include/nodes/pathnodes.h
@@ -1188,6 +1188,8 @@ struct IndexOptInfo
 	bool		immediate;
 	/* true if index doesn't really exist */
 	bool		hypothetical;
+	/* is index enable? */
+  bool		enabled;
 
 	/*
 	 * Remaining fields are copied from the index AM's API struct
diff --git a/src/test/regress/expected/create_index.out b/src/test/regress/expected/create_index.out
index d3358dfc39..57add757aa 100644
--- a/src/test/regress/expected/create_index.out
+++ b/src/test/regress/expected/create_index.out
@@ -2965,6 +2965,256 @@ ERROR:  REINDEX SCHEMA cannot run inside a transaction block
 END;
 -- concurrently
 REINDEX SCHEMA CONCURRENTLY schema_to_reindex;
+-- Test enable/disable functionality for indexes
+-- Setup
+CREATE TABLE enable_disable_test(id int primary key, data text);
+INSERT INTO enable_disable_test SELECT g, 'data ' || g FROM generate_series(1, 1000) g;
+-- CREATE INDEX with ENABLED/DISABLED
+CREATE INDEX enable_disable_idx1 ON enable_disable_test(data) DISABLE;
+CREATE INDEX enable_disable_idx2 ON enable_disable_test(data);
+SELECT indexrelid::regclass, indisvalid, indisready, indislive, indisenabled
+FROM pg_index
+WHERE indrelid = 'enable_disable_test'::regclass
+ORDER BY indexrelid::regclass::text;
+        indexrelid        | indisvalid | indisready | indislive | indisenabled 
+--------------------------+------------+------------+-----------+--------------
+ enable_disable_idx1      | t          | t          | t         | f
+ enable_disable_idx2      | t          | t          | t         | t
+ enable_disable_test_pkey | t          | t          | t         | t
+(3 rows)
+
+-- ALTER INDEX ... ENABLE/DISABLE
+-- Before
+SELECT indexrelid::regclass, indisvalid, indisready, indislive, indisenabled
+FROM pg_index
+WHERE indrelid = 'enable_disable_test'::regclass
+ORDER BY indexrelid::regclass::text;
+        indexrelid        | indisvalid | indisready | indislive | indisenabled 
+--------------------------+------------+------------+-----------+--------------
+ enable_disable_idx1      | t          | t          | t         | f
+ enable_disable_idx2      | t          | t          | t         | t
+ enable_disable_test_pkey | t          | t          | t         | t
+(3 rows)
+
+ALTER INDEX enable_disable_idx2 DISABLE;
+NOTICE:  index "enable_disable_idx2" is now disabled
+-- After
+SELECT indexrelid::regclass, indisvalid, indisready, indislive, indisenabled
+FROM pg_index
+WHERE indrelid = 'enable_disable_test'::regclass
+ORDER BY indexrelid::regclass::text;
+        indexrelid        | indisvalid | indisready | indislive | indisenabled 
+--------------------------+------------+------------+-----------+--------------
+ enable_disable_idx1      | t          | t          | t         | f
+ enable_disable_idx2      | t          | t          | t         | f
+ enable_disable_test_pkey | t          | t          | t         | t
+(3 rows)
+
+-- Enable all indexes
+ALTER INDEX enable_disable_idx2 ENABLE;
+NOTICE:  index "enable_disable_idx2" is now enabled
+ALTER INDEX enable_disable_idx1 ENABLE;
+NOTICE:  index "enable_disable_idx1" is now enabled
+SELECT indexrelid::regclass, indisvalid, indisready, indislive, indisenabled
+FROM pg_index
+WHERE indrelid = 'enable_disable_test'::regclass
+ORDER BY indexrelid::regclass::text;
+        indexrelid        | indisvalid | indisready | indislive | indisenabled 
+--------------------------+------------+------------+-----------+--------------
+ enable_disable_idx1      | t          | t          | t         | t
+ enable_disable_idx2      | t          | t          | t         | t
+ enable_disable_test_pkey | t          | t          | t         | t
+(3 rows)
+
+-- REINDEX TABLE
+REINDEX TABLE enable_disable_test;
+SELECT indexrelid::regclass, indisvalid, indisready, indislive, indisenabled
+FROM pg_index
+WHERE indrelid = 'enable_disable_test'::regclass
+ORDER BY indexrelid::regclass::text;
+        indexrelid        | indisvalid | indisready | indislive | indisenabled 
+--------------------------+------------+------------+-----------+--------------
+ enable_disable_idx1      | t          | t          | t         | t
+ enable_disable_idx2      | t          | t          | t         | t
+ enable_disable_test_pkey | t          | t          | t         | t
+(3 rows)
+
+-- REINDEX INDEX with enable/disable
+ALTER INDEX enable_disable_idx1 DISABLE;
+NOTICE:  index "enable_disable_idx1" is now disabled
+REINDEX INDEX enable_disable_idx1;
+SELECT indexrelid::regclass, indisvalid, indisready, indislive, indisenabled
+FROM pg_index
+WHERE indrelid = 'enable_disable_test'::regclass
+ORDER BY indexrelid::regclass::text;
+        indexrelid        | indisvalid | indisready | indislive | indisenabled 
+--------------------------+------------+------------+-----------+--------------
+ enable_disable_idx1      | t          | t          | t         | f
+ enable_disable_idx2      | t          | t          | t         | t
+ enable_disable_test_pkey | t          | t          | t         | t
+(3 rows)
+
+-- REINDEX INDEX CONCURRENTLY with enable/disable
+ALTER INDEX enable_disable_idx1 ENABLE;
+NOTICE:  index "enable_disable_idx1" is now enabled
+REINDEX INDEX enable_disable_idx1;
+SELECT indexrelid::regclass, indisvalid, indisready, indislive, indisenabled
+FROM pg_index
+WHERE indrelid = 'enable_disable_test'::regclass
+ORDER BY indexrelid::regclass::text;
+        indexrelid        | indisvalid | indisready | indislive | indisenabled 
+--------------------------+------------+------------+-----------+--------------
+ enable_disable_idx1      | t          | t          | t         | t
+ enable_disable_idx2      | t          | t          | t         | t
+ enable_disable_test_pkey | t          | t          | t         | t
+(3 rows)
+
+-- Test ENABLE/DISABLE on TOAST index
+CREATE TABLE toast_test (id int primary key, data text);
+INSERT INTO toast_test SELECT g, repeat('long text ', 1000) FROM generate_series(1, 10) g;
+-- Check initial state of TOAST index
+SELECT indisvalid, indisready, indislive, indisenabled
+FROM pg_index
+WHERE indexrelid = (SELECT indexrelid FROM pg_index WHERE indrelid = (SELECT reltoastrelid FROM pg_class WHERE oid = 'toast_test'::regclass));
+ indisvalid | indisready | indislive | indisenabled 
+------------+------------+-----------+--------------
+ t          | t          | t         | t
+(1 row)
+
+-- Disable TOAST index
+ALTER INDEX pg_toast.pg_toast_16385_index DISABLE;
+ERROR:  relation "pg_toast.pg_toast_16385_index" does not exist
+-- Check state after disabling TOAST index
+SELECT indisvalid, indisready, indislive, indisenabled
+FROM pg_index
+WHERE indexrelid = (SELECT indexrelid FROM pg_index WHERE indrelid = (SELECT reltoastrelid FROM pg_class WHERE oid = 'toast_test'::regclass));
+ indisvalid | indisready | indislive | indisenabled 
+------------+------------+-----------+--------------
+ t          | t          | t         | t
+(1 row)
+
+-- Enable TOAST index
+ALTER INDEX pg_toast.pg_toast_16385_index ENABLE;
+ERROR:  relation "pg_toast.pg_toast_16385_index" does not exist
+-- Check state after enabling TOAST index
+SELECT indisvalid, indisready, indislive, indisenabled
+FROM pg_index
+WHERE indexrelid = (SELECT indexrelid FROM pg_index WHERE indrelid = (SELECT reltoastrelid FROM pg_class WHERE oid = 'toast_test'::regclass));
+ indisvalid | indisready | indislive | indisenabled 
+------------+------------+-----------+--------------
+ t          | t          | t         | t
+(1 row)
+
+-- Test CREATE TABLE with UNIQUE constraint
+CREATE TABLE unique_constraint_test (id int UNIQUE, data text);
+INSERT INTO unique_constraint_test SELECT g, 'data ' || g FROM generate_series(1, 1000) g;
+SELECT indexrelid::regclass, indisvalid, indisready, indislive, indisenabled
+FROM pg_index
+WHERE indrelid = 'unique_constraint_test'::regclass;
+          indexrelid           | indisvalid | indisready | indislive | indisenabled 
+-------------------------------+------------+------------+-----------+--------------
+ unique_constraint_test_id_key | t          | t          | t         | t
+(1 row)
+
+-- Test that the unique constraint index is used
+EXPLAIN (COSTS OFF) SELECT * FROM unique_constraint_test WHERE id = 500;
+                                QUERY PLAN                                
+--------------------------------------------------------------------------
+ Index Scan using unique_constraint_test_id_key on unique_constraint_test
+   Index Cond: (id = 500)
+(2 rows)
+
+EXPLAIN (COSTS OFF) SELECT * FROM unique_constraint_test WHERE id IN (100, 200, 300);
+                         QUERY PLAN                          
+-------------------------------------------------------------
+ Bitmap Heap Scan on unique_constraint_test
+   Recheck Cond: (id = ANY ('{100,200,300}'::integer[]))
+   ->  Bitmap Index Scan on unique_constraint_test_id_key
+         Index Cond: (id = ANY ('{100,200,300}'::integer[]))
+(4 rows)
+
+-- Test CREATE TABLE with INDEX
+CREATE TABLE index_test (id int, data text);
+INSERT INTO index_test SELECT g, 'data ' || g FROM generate_series(1, 1000) g;
+CREATE INDEX ON index_test (data);
+SELECT indexrelid::regclass, indisvalid, indisready, indislive, indisenabled
+FROM pg_index
+WHERE indrelid = 'index_test'::regclass;
+     indexrelid      | indisvalid | indisready | indislive | indisenabled 
+---------------------+------------+------------+-----------+--------------
+ index_test_data_idx | t          | t          | t         | t
+(1 row)
+
+-- Test that the index is used
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE data = 'data 500';
+                   QUERY PLAN                   
+------------------------------------------------
+ Bitmap Heap Scan on index_test
+   Recheck Cond: (data = 'data 500'::text)
+   ->  Bitmap Index Scan on index_test_data_idx
+         Index Cond: (data = 'data 500'::text)
+(4 rows)
+
+-- Test index usage with joins
+CREATE TABLE join_test (id int PRIMARY KEY, ref_id int);
+INSERT INTO join_test SELECT g, g % 100 FROM generate_series(1, 1000) g;
+EXPLAIN (COSTS OFF)
+SELECT jt.id, it.data
+FROM join_test jt
+JOIN index_test it ON jt.ref_id = it.id
+WHERE jt.id BETWEEN 100 AND 200;
+                          QUERY PLAN                           
+---------------------------------------------------------------
+ Hash Join
+   Hash Cond: (it.id = jt.ref_id)
+   ->  Seq Scan on index_test it
+   ->  Hash
+         ->  Bitmap Heap Scan on join_test jt
+               Recheck Cond: ((id >= 100) AND (id <= 200))
+               ->  Bitmap Index Scan on join_test_pkey
+                     Index Cond: ((id >= 100) AND (id <= 200))
+(8 rows)
+
+-- Test index usage with ORDER BY
+EXPLAIN (COSTS OFF)
+SELECT *
+FROM index_test
+ORDER BY data
+LIMIT 10;
+                        QUERY PLAN                        
+----------------------------------------------------------
+ Limit
+   ->  Index Scan using index_test_data_idx on index_test
+(2 rows)
+
+-- Test disabling an index and its effect on query plan
+ALTER INDEX index_test_data_idx DISABLE;
+NOTICE:  index "index_test_data_idx" is now disabled
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE data = 'data 500';
+             QUERY PLAN              
+-------------------------------------
+ Seq Scan on index_test
+   Filter: (data = 'data 500'::text)
+(2 rows)
+
+-- Re-enable the index
+ALTER INDEX index_test_data_idx ENABLE;
+NOTICE:  index "index_test_data_idx" is now enabled
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE data = 'data 500';
+                   QUERY PLAN                   
+------------------------------------------------
+ Bitmap Heap Scan on index_test
+   Recheck Cond: (data = 'data 500'::text)
+   ->  Bitmap Index Scan on index_test_data_idx
+         Index Cond: (data = 'data 500'::text)
+(4 rows)
+
+-- Clean up
+DROP TABLE enable_disable_test;
+DROP TABLE toast_test;
+DROP TABLE unique_constraint_test;
+DROP TABLE join_test;
+DROP TABLE index_test;
 -- Failure for unauthorized user
 CREATE ROLE regress_reindexuser NOLOGIN;
 SET SESSION ROLE regress_reindexuser;
diff --git a/src/test/regress/sql/create_index.sql b/src/test/regress/sql/create_index.sql
index fe162cc7c3..d599717c6f 100644
--- a/src/test/regress/sql/create_index.sql
+++ b/src/test/regress/sql/create_index.sql
@@ -1297,6 +1297,146 @@ END;
 -- concurrently
 REINDEX SCHEMA CONCURRENTLY schema_to_reindex;
 
+-- Test enable/disable functionality for indexes
+
+-- Setup
+CREATE TABLE enable_disable_test(id int primary key, data text);
+INSERT INTO enable_disable_test SELECT g, 'data ' || g FROM generate_series(1, 1000) g;
+
+-- CREATE INDEX with ENABLED/DISABLED
+CREATE INDEX enable_disable_idx1 ON enable_disable_test(data) DISABLE;
+CREATE INDEX enable_disable_idx2 ON enable_disable_test(data);
+SELECT indexrelid::regclass, indisvalid, indisready, indislive, indisenabled
+FROM pg_index
+WHERE indrelid = 'enable_disable_test'::regclass
+ORDER BY indexrelid::regclass::text;
+
+-- ALTER INDEX ... ENABLE/DISABLE
+-- Before
+SELECT indexrelid::regclass, indisvalid, indisready, indislive, indisenabled
+FROM pg_index
+WHERE indrelid = 'enable_disable_test'::regclass
+ORDER BY indexrelid::regclass::text;
+
+ALTER INDEX enable_disable_idx2 DISABLE;
+-- After
+SELECT indexrelid::regclass, indisvalid, indisready, indislive, indisenabled
+FROM pg_index
+WHERE indrelid = 'enable_disable_test'::regclass
+ORDER BY indexrelid::regclass::text;
+
+-- Enable all indexes
+ALTER INDEX enable_disable_idx2 ENABLE;
+ALTER INDEX enable_disable_idx1 ENABLE;
+SELECT indexrelid::regclass, indisvalid, indisready, indislive, indisenabled
+FROM pg_index
+WHERE indrelid = 'enable_disable_test'::regclass
+ORDER BY indexrelid::regclass::text;
+
+-- REINDEX TABLE
+REINDEX TABLE enable_disable_test;
+SELECT indexrelid::regclass, indisvalid, indisready, indislive, indisenabled
+FROM pg_index
+WHERE indrelid = 'enable_disable_test'::regclass
+ORDER BY indexrelid::regclass::text;
+
+-- REINDEX INDEX with enable/disable
+ALTER INDEX enable_disable_idx1 DISABLE;
+REINDEX INDEX enable_disable_idx1;
+SELECT indexrelid::regclass, indisvalid, indisready, indislive, indisenabled
+FROM pg_index
+WHERE indrelid = 'enable_disable_test'::regclass
+ORDER BY indexrelid::regclass::text;
+
+-- REINDEX INDEX CONCURRENTLY with enable/disable
+ALTER INDEX enable_disable_idx1 ENABLE;
+REINDEX INDEX enable_disable_idx1;
+SELECT indexrelid::regclass, indisvalid, indisready, indislive, indisenabled
+FROM pg_index
+WHERE indrelid = 'enable_disable_test'::regclass
+ORDER BY indexrelid::regclass::text;
+
+-- Test ENABLE/DISABLE on TOAST index
+CREATE TABLE toast_test (id int primary key, data text);
+INSERT INTO toast_test SELECT g, repeat('long text ', 1000) FROM generate_series(1, 10) g;
+
+-- Check initial state of TOAST index
+SELECT indisvalid, indisready, indislive, indisenabled
+FROM pg_index
+WHERE indexrelid = (SELECT indexrelid FROM pg_index WHERE indrelid = (SELECT reltoastrelid FROM pg_class WHERE oid = 'toast_test'::regclass));
+
+-- Disable TOAST index
+ALTER INDEX pg_toast.pg_toast_16385_index DISABLE;
+
+-- Check state after disabling TOAST index
+SELECT indisvalid, indisready, indislive, indisenabled
+FROM pg_index
+WHERE indexrelid = (SELECT indexrelid FROM pg_index WHERE indrelid = (SELECT reltoastrelid FROM pg_class WHERE oid = 'toast_test'::regclass));
+
+-- Enable TOAST index
+ALTER INDEX pg_toast.pg_toast_16385_index ENABLE;
+
+-- Check state after enabling TOAST index
+SELECT indisvalid, indisready, indislive, indisenabled
+FROM pg_index
+WHERE indexrelid = (SELECT indexrelid FROM pg_index WHERE indrelid = (SELECT reltoastrelid FROM pg_class WHERE oid = 'toast_test'::regclass));
+
+-- Test CREATE TABLE with UNIQUE constraint
+CREATE TABLE unique_constraint_test (id int UNIQUE, data text);
+INSERT INTO unique_constraint_test SELECT g, 'data ' || g FROM generate_series(1, 1000) g;
+SELECT indexrelid::regclass, indisvalid, indisready, indislive, indisenabled
+FROM pg_index
+WHERE indrelid = 'unique_constraint_test'::regclass;
+
+-- Test that the unique constraint index is used
+EXPLAIN (COSTS OFF) SELECT * FROM unique_constraint_test WHERE id = 500;
+EXPLAIN (COSTS OFF) SELECT * FROM unique_constraint_test WHERE id IN (100, 200, 300);
+
+-- Test CREATE TABLE with INDEX
+CREATE TABLE index_test (id int, data text);
+INSERT INTO index_test SELECT g, 'data ' || g FROM generate_series(1, 1000) g;
+CREATE INDEX ON index_test (data);
+SELECT indexrelid::regclass, indisvalid, indisready, indislive, indisenabled
+FROM pg_index
+WHERE indrelid = 'index_test'::regclass;
+
+-- Test that the index is used
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE data = 'data 500';
+
+-- Test index usage with joins
+CREATE TABLE join_test (id int PRIMARY KEY, ref_id int);
+INSERT INTO join_test SELECT g, g % 100 FROM generate_series(1, 1000) g;
+
+EXPLAIN (COSTS OFF)
+SELECT jt.id, it.data
+FROM join_test jt
+JOIN index_test it ON jt.ref_id = it.id
+WHERE jt.id BETWEEN 100 AND 200;
+
+-- Test index usage with ORDER BY
+EXPLAIN (COSTS OFF)
+SELECT *
+FROM index_test
+ORDER BY data
+LIMIT 10;
+
+-- Test disabling an index and its effect on query plan
+ALTER INDEX index_test_data_idx DISABLE;
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE data = 'data 500';
+
+-- Re-enable the index
+ALTER INDEX index_test_data_idx ENABLE;
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE data = 'data 500';
+
+-- Clean up
+DROP TABLE enable_disable_test;
+DROP TABLE toast_test;
+DROP TABLE unique_constraint_test;
+DROP TABLE join_test;
+DROP TABLE index_test;
+
 -- Failure for unauthorized user
 CREATE ROLE regress_reindexuser NOLOGIN;
 SET SESSION ROLE regress_reindexuser;
-- 
2.37.1 (Apple Git-137.1)

#12David Rowley
dgrowleyml@gmail.com
In reply to: Shayon Mukherjee (#10)
Re: [PATCH] Re: Proposal to Enable/Disable Index using ALTER INDEX

On Mon, 23 Sept 2024 at 05:43, Shayon Mukherjee <shayonj@gmail.com> wrote:

- Modified get_index_paths() and build_index_paths() to exclude disabled
indexes from consideration during query planning.

There are quite a large number of other places you also need to modify.

Here are 2 places where the index should be ignored but isn't:

1. expression indexes seem to still be used for statistical estimations:

create table b as select generate_series(1,1000)b;
create index on b((b%10));
analyze b;
explain select distinct b%10 from b;
-- HashAggregate (cost=23.00..23.12 rows=10 width=4)

alter index b_expr_idx disable;
explain select distinct b%10 from b;
-- HashAggregate (cost=23.00..23.12 rows=10 width=4) <-- should be 1000 rows

drop index b_expr_idx;
explain select distinct b%10 from b;
-- HashAggregate (cost=23.00..35.50 rows=1000 width=4)

2. Indexes seem to still be used for join removals.

create table c (c int primary key);
explain select c1.* from c c1 left join c c2 on c1.c=c2.c; --
correctly removes join.
alter index c_pkey disable;
explain select c1.* from c c1 left join c c2 on c1.c=c2.c; -- should
not remove join.

Please carefully look over all places that RelOptInfo.indexlist is
looked at and consider skipping disabled indexes. Please also take
time to find SQL that exercises each of those places so you can verify
that the behaviour is correct after your change. This is also a good
way to learn exactly all cases where indexes are used. Using this
method would have led you to find places like
rel_supports_distinctness(), where you should be skipping disabled
indexes.

The planner should not be making use of disabled indexes for any
optimisations at all.

- catversion.h is updated with a new CATALOG_VERSION_NO to reflect change in pg_index
schema.

Please leave that up to the committer. Patch authors doing this just
results in the patch no longer applying as soon as someone commits a
version bump.

Also, please get rid of these notices. The command tag serves that
purpose. It's not interesting that the index is already disabled.

# alter index a_pkey disable;
NOTICE: index "a_pkey" is now disabled
ALTER INDEX
# alter index a_pkey disable;
NOTICE: index "a_pkey" is already disabled
ALTER INDEX

I've only given the code a very quick glance. I don't quite understand
why you're checking the index is enabled in create_index_paths() and
get_index_paths(). I think the check should be done only in
create_index_paths(). Primarily, you'll find code such as "if
(index->indpred != NIL && !index->predOK)" in the locations you need
to consider skipping the disabled index. I think your new code should
be located very close to those places or perhaps within the same if
condition unless it makes it overly complex for the human reader.

I think the documents should also mention that disabling an index is a
useful way to verify an index is not being used before dropping it as
the index can be enabled again at the first sign that performance has
been effected. (It might also be good to mention that checking
pg_stat_user_indexes.idx_scan should be the first port of call when
checking for unused indexes)

David

#13Shayon Mukherjee
shayonj@gmail.com
In reply to: David Rowley (#12)
Re: [PATCH] Proposal to Enable/Disable Index using ALTER INDEX

Hi David,

Thank you so much for the review and pointers. I totally missed expression indexes. I am going to do another proper pass along with your feedback and follow up with an updated patch and any questions.

Excited to be learning so much about the internals.
Shayon

Show quoted text

On Sep 22, 2024, at 6:44 PM, David Rowley <dgrowleyml@gmail.com> wrote:

On Mon, 23 Sept 2024 at 05:43, Shayon Mukherjee <shayonj@gmail.com> wrote:

- Modified get_index_paths() and build_index_paths() to exclude disabled
indexes from consideration during query planning.

There are quite a large number of other places you also need to modify.

Here are 2 places where the index should be ignored but isn't:

1. expression indexes seem to still be used for statistical estimations:

create table b as select generate_series(1,1000)b;
create index on b((b%10));
analyze b;
explain select distinct b%10 from b;
-- HashAggregate (cost=23.00..23.12 rows=10 width=4)

alter index b_expr_idx disable;
explain select distinct b%10 from b;
-- HashAggregate (cost=23.00..23.12 rows=10 width=4) <-- should be 1000 rows

drop index b_expr_idx;
explain select distinct b%10 from b;
-- HashAggregate (cost=23.00..35.50 rows=1000 width=4)

2. Indexes seem to still be used for join removals.

create table c (c int primary key);
explain select c1.* from c c1 left join c c2 on c1.c=c2.c; --
correctly removes join.
alter index c_pkey disable;
explain select c1.* from c c1 left join c c2 on c1.c=c2.c; -- should
not remove join.

Please carefully look over all places that RelOptInfo.indexlist is
looked at and consider skipping disabled indexes. Please also take
time to find SQL that exercises each of those places so you can verify
that the behaviour is correct after your change. This is also a good
way to learn exactly all cases where indexes are used. Using this
method would have led you to find places like
rel_supports_distinctness(), where you should be skipping disabled
indexes.

The planner should not be making use of disabled indexes for any
optimisations at all.

- catversion.h is updated with a new CATALOG_VERSION_NO to reflect change in pg_index
schema.

Please leave that up to the committer. Patch authors doing this just
results in the patch no longer applying as soon as someone commits a
version bump.

Also, please get rid of these notices. The command tag serves that
purpose. It's not interesting that the index is already disabled.

# alter index a_pkey disable;
NOTICE: index "a_pkey" is now disabled
ALTER INDEX
# alter index a_pkey disable;
NOTICE: index "a_pkey" is already disabled
ALTER INDEX

I've only given the code a very quick glance. I don't quite understand
why you're checking the index is enabled in create_index_paths() and
get_index_paths(). I think the check should be done only in
create_index_paths(). Primarily, you'll find code such as "if
(index->indpred != NIL && !index->predOK)" in the locations you need
to consider skipping the disabled index. I think your new code should
be located very close to those places or perhaps within the same if
condition unless it makes it overly complex for the human reader.

I think the documents should also mention that disabling an index is a
useful way to verify an index is not being used before dropping it as
the index can be enabled again at the first sign that performance has
been effected. (It might also be good to mention that checking
pg_stat_user_indexes.idx_scan should be the first port of call when
checking for unused indexes)

David

#14Peter Eisentraut
peter@eisentraut.org
In reply to: Shayon Mukherjee (#1)
Re: Proposal to Enable/Disable Index using ALTER INDEX

On 09.09.24 23:38, Shayon Mukherjee wrote:

*Problem*:
Adding and removing indexes is a common operation in PostgreSQL. On
larger databases, however, these operations can be resource-intensive.
When evaluating the performance impact of one or more indexes, dropping
them might not be ideal since as a user you may want a quicker way to
test their effects without fully committing to removing & adding them
back again. Which can be a time taking operation on larger tables.

*Proposal*:
I propose adding an ALTER INDEX command that allows for enabling or
disabling an index globally. This could look something like:

ALTER INDEX index_name ENABLE;
ALTER INDEX index_name DISABLE;

A disabled index would still receive updates and enforce constraints as
usual but would not be used for queries. This allows users to assess
whether an index impacts query performance before deciding to drop it
entirely.

I think a better approach would be to make the list of disabled indexes
a GUC setting, which would then internally have an effect similar to
enable_indexscan, meaning it would make the listed indexes unattractive
to the planner.

This seems better than the proposed DDL command, because you'd be able
to use this per-session, instead of forcing a global state, and even
unprivileged users could use it.

(I think we have had proposals like this before, but I can't find the
discussion I'm thinking of right now.)

#15Shayon Mukherjee
shayonj@gmail.com
In reply to: Peter Eisentraut (#14)
Re: Proposal to Enable/Disable Index using ALTER INDEX

That's a good point.

+1 for the idea of the GUC setting, especially since, as you mentioned, it allows unprivileged users to access it and being per-session..

I am happy to draft a patch for this as well. I think I have a working idea so far of where the necessary checks might go. However if you don’t mind, can you elaborate further on how the effect would be similar to enable_indexscan?

I was thinking we could introduce a new GUC option called `disabled_indexes` and perform a check against in all places for each index being considered with its OID via get_relname_relid through a helper function in the various places we need to prompt the planner to not use the index (like in indxpath.c as an example).

Curious to learn if you have a different approach in mind perhaps?

Thank you,
Shayon

Show quoted text

On Sep 23, 2024, at 11:14 AM, Peter Eisentraut <peter@eisentraut.org> wrote:

On 09.09.24 23:38, Shayon Mukherjee wrote:

*Problem*:
Adding and removing indexes is a common operation in PostgreSQL. On larger databases, however, these operations can be resource-intensive. When evaluating the performance impact of one or more indexes, dropping them might not be ideal since as a user you may want a quicker way to test their effects without fully committing to removing & adding them back again. Which can be a time taking operation on larger tables.
*Proposal*:
I propose adding an ALTER INDEX command that allows for enabling or disabling an index globally. This could look something like:
ALTER INDEX index_name ENABLE;
ALTER INDEX index_name DISABLE;
A disabled index would still receive updates and enforce constraints as usual but would not be used for queries. This allows users to assess whether an index impacts query performance before deciding to drop it entirely.

I think a better approach would be to make the list of disabled indexes a GUC setting, which would then internally have an effect similar to enable_indexscan, meaning it would make the listed indexes unattractive to the planner.

This seems better than the proposed DDL command, because you'd be able to use this per-session, instead of forcing a global state, and even unprivileged users could use it.

(I think we have had proposals like this before, but I can't find the discussion I'm thinking of right now.)

#16Shayon Mukherjee
shayonj@gmail.com
In reply to: Shayon Mukherjee (#15)
Re: Proposal to Enable/Disable Index using ALTER INDEX

I found an old thread here [0]https://postgrespro.com/list/id/20151212.112536.1628974191058745674.t-ishii@sraoss.co.jp.

Also, a question: If we go with the GUC approach, how do we expect `pg_get_indexdef` to behave?

I suppose it would behave no differently than it otherwise would, because there's no new SQL grammar to support and, given its GUC status, it seems reasonable that `pg_get_indexdef` doesn’t reflect whether an index is enabled or not.

If so, then I wonder if using a dedicated `ALTER` command and keeping the state in `pg_index` would be better for consistency's sake?

[0]: https://postgrespro.com/list/id/20151212.112536.1628974191058745674.t-ishii@sraoss.co.jp

Thank you
Shayon

Show quoted text

On Sep 23, 2024, at 4:51 PM, Shayon Mukherjee <shayonj@gmail.com> wrote:

That's a good point.

+1 for the idea of the GUC setting, especially since, as you mentioned, it allows unprivileged users to access it and being per-session..

I am happy to draft a patch for this as well. I think I have a working idea so far of where the necessary checks might go. However if you don’t mind, can you elaborate further on how the effect would be similar to enable_indexscan?

I was thinking we could introduce a new GUC option called `disabled_indexes` and perform a check against in all places for each index being considered with its OID via get_relname_relid through a helper function in the various places we need to prompt the planner to not use the index (like in indxpath.c as an example).

Curious to learn if you have a different approach in mind perhaps?

Thank you,
Shayon

On Sep 23, 2024, at 11:14 AM, Peter Eisentraut <peter@eisentraut.org> wrote:

On 09.09.24 23:38, Shayon Mukherjee wrote:

*Problem*:
Adding and removing indexes is a common operation in PostgreSQL. On larger databases, however, these operations can be resource-intensive. When evaluating the performance impact of one or more indexes, dropping them might not be ideal since as a user you may want a quicker way to test their effects without fully committing to removing & adding them back again. Which can be a time taking operation on larger tables.
*Proposal*:
I propose adding an ALTER INDEX command that allows for enabling or disabling an index globally. This could look something like:
ALTER INDEX index_name ENABLE;
ALTER INDEX index_name DISABLE;
A disabled index would still receive updates and enforce constraints as usual but would not be used for queries. This allows users to assess whether an index impacts query performance before deciding to drop it entirely.

I think a better approach would be to make the list of disabled indexes a GUC setting, which would then internally have an effect similar to enable_indexscan, meaning it would make the listed indexes unattractive to the planner.

This seems better than the proposed DDL command, because you'd be able to use this per-session, instead of forcing a global state, and even unprivileged users could use it.

(I think we have had proposals like this before, but I can't find the discussion I'm thinking of right now.)

#17David Rowley
dgrowleyml@gmail.com
In reply to: Peter Eisentraut (#14)
Re: Proposal to Enable/Disable Index using ALTER INDEX

On Tue, 24 Sept 2024 at 03:14, Peter Eisentraut <peter@eisentraut.org> wrote:

On 09.09.24 23:38, Shayon Mukherjee wrote:

ALTER INDEX index_name ENABLE;
ALTER INDEX index_name DISABLE;

I think a better approach would be to make the list of disabled indexes
a GUC setting, which would then internally have an effect similar to
enable_indexscan, meaning it would make the listed indexes unattractive
to the planner.

I understand the last discussion went down that route too. For me, it
seems strange that adding some global variable is seen as cleaner than
storing the property in the same location as all the other index
properties.

How would you ensure no cached plans are still using the index after
changing the GUC?

This seems better than the proposed DDL command, because you'd be able
to use this per-session, instead of forcing a global state, and even
unprivileged users could use it.

That's true.

(I think we have had proposals like this before, but I can't find the
discussion I'm thinking of right now.)

I think it's the one that was already linked by Nathan. [1]/messages/by-id/ed8c9ed7-bb5d-aaec-065b-ad4893645deb@2ndQuadrant.com? The GUC
seems to have been first suggested on the same thread in [2]/messages/by-id/29800.1529359024@sss.pgh.pa.us.

David

[1]: /messages/by-id/ed8c9ed7-bb5d-aaec-065b-ad4893645deb@2ndQuadrant.com
[2]: /messages/by-id/29800.1529359024@sss.pgh.pa.us

#18Shayon Mukherjee
shayonj@gmail.com
In reply to: David Rowley (#17)
Re: Proposal to Enable/Disable Index using ALTER INDEX

On Mon, Sep 23, 2024 at 8:31 PM David Rowley <dgrowleyml@gmail.com> wrote:

On Tue, 24 Sept 2024 at 03:14, Peter Eisentraut <peter@eisentraut.org>
wrote:

On 09.09.24 23:38, Shayon Mukherjee wrote:

ALTER INDEX index_name ENABLE;
ALTER INDEX index_name DISABLE;

I think a better approach would be to make the list of disabled indexes
a GUC setting, which would then internally have an effect similar to
enable_indexscan, meaning it would make the listed indexes unattractive
to the planner.

I understand the last discussion went down that route too. For me, it
seems strange that adding some global variable is seen as cleaner than
storing the property in the same location as all the other index
properties.

That was my first instinct as well. Although, being able to control this
setting on a per session level and as an unprivileged user is somewhat
attractive.

How would you ensure no cached plans are still using the index after
changing the GUC?

Could we call ResetPlanCache() to invalidate all plan caches from the
assign_ hook on GUC when it's set (and doesn't match the old value).
Something like this (assuming the GUC is called `disabled_indexes`)

void
assign_disabled_indexes(const char *newval, void *extra)
{
if (disabled_indexes != newval)
ResetPlanCache();
}

A bit heavy-handed, but perhaps it's OK, since it's not meant to be used
frequently also ?

This seems better than the proposed DDL command, because you'd be able
to use this per-session, instead of forcing a global state, and even
unprivileged users could use it.

That's true.

(I think we have had proposals like this before, but I can't find the
discussion I'm thinking of right now.)

I think it's the one that was already linked by Nathan. [1]? The GUC
seems to have been first suggested on the same thread in [2].

David

[1]
/messages/by-id/ed8c9ed7-bb5d-aaec-065b-ad4893645deb@2ndQuadrant.com
[2] /messages/by-id/29800.1529359024@sss.pgh.pa.us

Shayon

#19Maciek Sakrejda
m.sakrejda@gmail.com
In reply to: Shayon Mukherjee (#18)
Re: Proposal to Enable/Disable Index using ALTER INDEX

If one of the use cases is soft-dropping indexes, would a GUC approach
still support that? ALTER TABLE?

#20Shayon Mukherjee
shayonj@gmail.com
In reply to: Maciek Sakrejda (#19)
1 attachment(s)
Re: Proposal to Enable/Disable Index using ALTER INDEX

Hello,

Regarding GUC implementation for index disabling, I was imagining something
like the attached PATCH. The patch compiles and can be applied for testing.
It's not meant to be production ready, but I am sharing it as a way to get
a sense of the nuts and bolts. It requires more proper test cases and docs,
etc. Example towards the end of the email.

That said, I am still quite torn between GUC setting or having a dedicated
ALTER grammar. My additional thoughts which is mostly a summary of what
David and Peter have already very nicely raised earlier are:

- GUC allows a non-privileged user to disable one or more indexes per
session.

- If we think of the task of disabling indexes temporarily (without
stopping any updates to the index), then it feels more in the territory of
query tuning than index maintenance. In which case, a GUC setting makes
more sense and sits well with others in the team like enable_indexscan,
enable_indexonlyscan and so on.

- At the same time, as David pointed out earlier, GUC is also a global
setting and perhaps storing the state of whether or not an index is being
used is perhaps better situated along with other index properties in
pg_index.

- One of my original motivations for the proposal was also that we can
disable an index for _all_ sessions quickly without it impacting index
build and turn it back on quickly as well. To do so with GUC, we would need
to do something like the following, if I am not mistaken, in which case
that is not something an unprivileged user may be able to perform, so just
calling it out.

ALTER USER example_user SET disabled_indexes = 'idx_foo_bar';

- For an ALTER statement, I think an ALTER INDEX makes more sense than
ALTER TABLE, especially since we have the existing ALTER INDEX grammar and
functionality. But let me know if I am missing something here.

- Resetting plan cache could still be an open question for GUC. I was
wondering if we can reset the plan cache local to the session for GUC (like
the one in the PATCH attached) and if that is enough? This concern doesn't
apply with managing property in pg_index.

- With a GUC attribute, the state of an index being enabled/disabled won't
be captured in pg_get_indexdef(), and that is likely OK, but maybe that
would need to be made explicit through docs.

Example 1

CREATE TABLE b AS SELECT generate_series(1,1000) AS b;
CREATE INDEX ON b((b%10));
ANALYZE b;
EXPLAIN SELECT DISTINCT b%10 FROM b;

SET disabled_indexes = 'b_expr_idx';

EXPLAIN SELECT DISTINCT b%10 FROM b; -- HashAggregate rows=10000

Example 2

CREATE TABLE disabled_index_test(id int PRIMARY KEY, data text);
INSERT INTO disabled_index_test SELECT g, 'data ' || g FROM
generate_series(1, 1000) g;
CREATE INDEX disabled_index_idx1 ON disabled_index_test(data);
EXPLAIN (COSTS OFF) SELECT * FROM disabled_index_test WHERE data = 'data
500';

SET disabled_indexes = 'b_expr_idx, disabled_index_idx1';

EXPLAIN SELECT * FROM disabled_index_test WHERE data = 'data 500'; -- no
index is used

Wrapping up...

I am sure there are things I am missing or unintentionally overlooking.
Since this would be a nice feature to have, I'd love some guidance on which
approach seems like a good next step to take. I am happy to work
accordingly on the patch.

Thank you
Shayon

On Tue, Sep 24, 2024 at 12:38 AM Maciek Sakrejda <m.sakrejda@gmail.com>
wrote:

If one of the use cases is soft-dropping indexes, would a GUC approach
still support that? ALTER TABLE?

--
Kind Regards,
Shayon Mukherjee

Attachments:

v1-0001-Proof-of-Concept-Ability-to-enable-disable-indexe.patchapplication/octet-stream; name=v1-0001-Proof-of-Concept-Ability-to-enable-disable-indexe.patchDownload
From e796e322ffbba563b1d31f9c0024a96bcc81a430 Mon Sep 17 00:00:00 2001
From: Shayon Mukherjee <shayonj@gmail.com>
Date: Tue, 24 Sep 2024 09:16:14 -0400
Subject: [PATCH v1] Proof of Concept: Ability to enable/disable indexes
 through GUC

---
 src/backend/optimizer/path/indxpath.c | 52 +++++++++++++++++++++++++++
 src/backend/utils/adt/selfuncs.c      |  3 ++
 src/backend/utils/misc/guc_tables.c   | 14 ++++++++
 src/include/optimizer/optimizer.h     |  8 +++++
 4 files changed, 77 insertions(+)

diff --git a/src/backend/optimizer/path/indxpath.c b/src/backend/optimizer/path/indxpath.c
index c0fcc7d78d..5b88aeecd4 100644
--- a/src/backend/optimizer/path/indxpath.c
+++ b/src/backend/optimizer/path/indxpath.c
@@ -35,6 +35,8 @@
 #include "utils/lsyscache.h"
 #include "utils/selfuncs.h"
 
+#include "utils/plancache.h"
+#include "utils/varlena.h"
 
 /* XXX see PartCollMatchesExprColl */
 #define IndexCollMatchesExprColl(idxcollation, exprcollation) \
@@ -265,6 +267,10 @@ create_index_paths(PlannerInfo *root, RelOptInfo *rel)
 		if (index->indpred != NIL && !index->predOK)
 			continue;
 
+		// Ignore if index is asked to be disabled
+		if (is_index_disabled(index->indexoid))
+			continue;
+
 		/*
 		 * Identify the restriction clauses that can match the index.
 		 */
@@ -3757,3 +3763,49 @@ is_pseudo_constant_for_index(PlannerInfo *root, Node *expr, IndexOptInfo *index)
 		return false;			/* no good, volatile comparison value */
 	return true;
 }
+
+
+bool
+is_index_disabled(Oid indexId)
+{
+		char       *rawnames;
+		List       *namelist;
+		ListCell   *l;
+
+		if (!disabled_indexes || disabled_indexes[0] == '\0')
+			return false;
+
+		rawnames = pstrdup(disabled_indexes);
+		if (!SplitIdentifierString(rawnames, ',', &namelist))
+		{
+			/* syntax error in name list */
+			pfree(rawnames);
+			list_free(namelist);
+			return false;
+		}
+
+		foreach(l, namelist)
+		{
+			char	*curname = (char *) lfirst(l);
+			Oid		indexOid;
+
+			indexOid = get_relname_relid(curname, get_rel_namespace(indexId));
+			if (indexOid == indexId)
+				{
+					pfree(rawnames);
+					list_free(namelist);
+					return true;
+				}
+		}
+
+		pfree(rawnames);
+		list_free(namelist);
+		return false;
+}
+
+void
+assign_disabled_indexes(const char *newval, void *extra)
+{
+	if (disabled_indexes != newval)
+		ResetPlanCache();
+}
diff --git a/src/backend/utils/adt/selfuncs.c b/src/backend/utils/adt/selfuncs.c
index 03d7fb5f48..7491d4a768 100644
--- a/src/backend/utils/adt/selfuncs.c
+++ b/src/backend/utils/adt/selfuncs.c
@@ -5152,6 +5152,9 @@ examine_variable(PlannerInfo *root, Node *node, int varRelid,
 
 			for (pos = 0; pos < index->ncolumns; pos++)
 			{
+				if (is_index_disabled(index->indexoid))
+					continue;
+
 				if (index->indexkeys[pos] == 0)
 				{
 					Node	   *indexkey;
diff --git a/src/backend/utils/misc/guc_tables.c b/src/backend/utils/misc/guc_tables.c
index 686309db58..dd588b7f8c 100644
--- a/src/backend/utils/misc/guc_tables.c
+++ b/src/backend/utils/misc/guc_tables.c
@@ -547,6 +547,7 @@ int			tcp_keepalives_interval;
 int			tcp_keepalives_count;
 int			tcp_user_timeout;
 
+
 /*
  * SSL renegotiation was been removed in PostgreSQL 9.5, but we tolerate it
  * being set to zero (meaning never renegotiate) for backward compatibility.
@@ -3500,6 +3501,7 @@ struct config_int ConfigureNamesInt[] =
 		check_autovacuum_work_mem, NULL, NULL
 	},
 
+
 	{
 		{"tcp_keepalives_idle", PGC_USERSET, CONN_AUTH_TCP,
 			gettext_noop("Time between issuing TCP keepalives."),
@@ -4783,6 +4785,18 @@ struct config_string ConfigureNamesString[] =
 		check_restrict_nonsystem_relation_kind, assign_restrict_nonsystem_relation_kind, NULL
 	},
 
+	{
+		{"disabled_indexes", PGC_USERSET, QUERY_TUNING_OTHER,
+			gettext_noop("Sets the list of indexes to be disabled for query planning."),
+			NULL,
+			GUC_LIST_INPUT | GUC_NOT_IN_SAMPLE
+		},
+		&disabled_indexes,
+		"",
+		NULL, assign_disabled_indexes, NULL
+	},
+
+
 	/* End-of-list marker */
 	{
 		{NULL, 0, 0, NULL, NULL}, NULL, NULL, NULL, NULL, NULL
diff --git a/src/include/optimizer/optimizer.h b/src/include/optimizer/optimizer.h
index 93e3dc719d..d96ee3e210 100644
--- a/src/include/optimizer/optimizer.h
+++ b/src/include/optimizer/optimizer.h
@@ -203,4 +203,12 @@ extern List *pull_var_clause(Node *node, int flags);
 extern Node *flatten_join_alias_vars(PlannerInfo *root, Query *query, Node *node);
 extern Node *flatten_group_exprs(PlannerInfo *root, Query *query, Node *node);
 
+// GUC support for disabled indexes
+/* Comma-separated list of indexes to be disabled for the planner */
+extern PGDLLIMPORT char *disabled_indexes;
+char 		*disabled_indexes;
+
+extern void assign_disabled_indexes(const char *newval, void *extra);
+extern bool is_index_disabled(Oid indexoid);
+
 #endif							/* OPTIMIZER_H */
-- 
2.37.1 (Apple Git-137.1)

#21Peter Eisentraut
peter@eisentraut.org
In reply to: Shayon Mukherjee (#15)
Re: Proposal to Enable/Disable Index using ALTER INDEX

On 23.09.24 22:51, Shayon Mukherjee wrote:

I am happy to draft a patch for this as well. I think I have a working
idea so far of where the necessary checks might go. However if you don’t
mind, can you elaborate further on how the effect would be similar to
enable_indexscan?

Planner settings like enable_indexscan used to just add a large number
(disable_cost) to the estimated plan node costs. It's a bit more
sophisticated in PG17. But in any case, I imagine "disabling an index"
could use the same mechanism. Or maybe not, maybe the setting would
just completely ignore the index.

#22Peter Eisentraut
peter@eisentraut.org
In reply to: David Rowley (#17)
Re: Proposal to Enable/Disable Index using ALTER INDEX

On 24.09.24 02:30, David Rowley wrote:

I understand the last discussion went down that route too. For me, it
seems strange that adding some global variable is seen as cleaner than
storing the property in the same location as all the other index
properties.

It's arguably not actually a property of the index, it's a property of
the user's session. Like, kind of, the search path is a session
property, not a property of a schema.

How would you ensure no cached plans are still using the index after
changing the GUC?

Something for the patch author to figure out. ;-)

#23Tom Lane
tgl@sss.pgh.pa.us
In reply to: Peter Eisentraut (#21)
Re: Proposal to Enable/Disable Index using ALTER INDEX

Peter Eisentraut <peter@eisentraut.org> writes:

On 23.09.24 22:51, Shayon Mukherjee wrote:

I am happy to draft a patch for this as well. I think I have a working
idea so far of where the necessary checks might go. However if you don’t
mind, can you elaborate further on how the effect would be similar to
enable_indexscan?

Planner settings like enable_indexscan used to just add a large number
(disable_cost) to the estimated plan node costs. It's a bit more
sophisticated in PG17. But in any case, I imagine "disabling an index"
could use the same mechanism. Or maybe not, maybe the setting would
just completely ignore the index.

Yeah, I'd be inclined to implement this by having create_index_paths
just not make any paths for rejected indexes. Or you could back up
another step and keep plancat.c from building IndexOptInfos for them.
The latter might have additional effects, such as preventing the plan
from relying on a uniqueness condition enforced by the index. Not
clear to me if that's desirable or not.

[ thinks... ] One good reason for implementing it in plancat.c is
that you'd have the index relation open and be able to see its name
for purposes of matching to the filter. Anywhere else, getting the
name would involve additional overhead.

regards, tom lane

#24Shayon Mukherjee
shayonj@gmail.com
In reply to: Peter Eisentraut (#21)
Re: Proposal to Enable/Disable Index using ALTER INDEX

Thank you for the historical context and working, I understand what you were referring to before now.

Shayon

Show quoted text

On Sep 24, 2024, at 2:08 PM, Peter Eisentraut <peter@eisentraut.org> wrote:

On 23.09.24 22:51, Shayon Mukherjee wrote:

I am happy to draft a patch for this as well. I think I have a working
idea so far of where the necessary checks might go. However if you don’t
mind, can you elaborate further on how the effect would be similar to
enable_indexscan?

Planner settings like enable_indexscan used to just add a large number (disable_cost) to the estimated plan node costs. It's a bit more sophisticated in PG17. But in any case, I imagine "disabling an index" could use the same mechanism. Or maybe not, maybe the setting would just completely ignore the index.

#25Shayon Mukherjee
shayonj@gmail.com
In reply to: Shayon Mukherjee (#20)
1 attachment(s)
Re: Proposal to Enable/Disable Index using ALTER INDEX

Hello,

I am back with a PATCH :). Thanks to everyone in the threads for all the helpful discussions.

This proposal is for a PATCH to introduce a GUC variable to disable specific indexes during query planning.

This is an alternative approach to the previous PATCH I had proposed and is improved upon after some of the recent discussions in the thread. The PATCH contains the relevant changes, regression tests, and documentation.

I went with the GUC approach to introduce a way for a user to disable indexes during query planning over dedicated SQL Grammar and introducing the `isenabled` attribute in `pg_index` for the following reasons:

- Inspired by the discussions brought in earlier about this setting being something that unprivileged users can benefit from versus an ALTER statement.
- A GUC variable felt more closely aligned with the query tuning purpose, which this feature would serve, over index maintenance, the state of which is more closely reflected in `pg_index`.

Implementation details:

The patch introduces a new GUC parameter `disabled_indexes` that allows users to specify a comma-separated list of indexes to be ignored during query planning. Key aspects:

- Adds a new `isdisabled` attribute to the `IndexOptInfo` structure.
- Modifies `get_relation_info` in `plancat.c` to skip disabled indexes entirely, thus reducing the number of places we need to check if an index is disabled or not.
- Implements GUC hooks for parameter validation and assignment.
- Resets the plan cache when the `disabled_indexes` list is modified through `ResetPlanCache()`

I chose to modify the logic within `get_relation_info` as compared to, say, reducing the cost to make the planner not consider an index during planning, mostly to keep the number of changes being introduced to a minimum and also the logic itself being self-contained and easier to under perhaps (?).

As mentioned before, this does not impact the building of the index. That still happens.

I have added regression tests for:

- Basic single-column and multi-column indexes
- Partial indexes
- Expression indexes
- Join indexes
- GIN and GiST indexes
- Covering indexes
- Range indexes
- Unique indexes and constraints

I'd love to hear any feedback on the proposed PATCH and also the overall approach.

Attachments:

v1-0001-Ability-to-enable-disable-indexes-through-GUC.patchapplication/octet-stream; name=v1-0001-Ability-to-enable-disable-indexes-through-GUC.patch; x-unix-mode=0644Download
From 24daa35ee5a7ae803df2f588c67a40f61538774f Mon Sep 17 00:00:00 2001
From: Shayon Mukherjee <shayonj@gmail.com>
Date: Thu, 26 Sep 2024 13:37:07 -0400
Subject: [PATCH v1] Ability to enable/disable indexes through GUC

The patch introduces a new GUC parameter `disabled_indexes` that allows users to specify a comma-separated list of indexes to be ignored during query planning. Key aspects:

- Adds a new `isdisabled` attribute to the `IndexOptInfo` structure.
- Modifies `get_relation_info` in `plancat.c` to skip disabled indexes entirely, thus reducing the number of places we need to check if an index is disabled or not.
- Implements GUC hooks for parameter validation and assignment.
- Resets the plan cache when the `disabled_indexes` list is modified through `ResetPlanCache()`

I chose to modify the logic within `get_relation_info` as compared to, say, reducing the cost to make the planner not consider an index during planning, mostly to keep the number of changes being introduced to a minimum and also the logic itself being self-contained and easier to under perhaps (?).

As mentioned before, this does not impact the building of the index. That still happens.

I have added regression tests for:

- Basic single-column and multi-column indexes
- Partial indexes
- Expression indexes
- Join indexes
- GIN and GiST indexes
- Covering indexes
- Range indexes
- Unique indexes and constraints
---
 doc/src/sgml/config.sgml                   |  18 ++
 src/backend/optimizer/util/plancat.c       | 102 +++++++
 src/backend/utils/misc/guc_tables.c        |  12 +
 src/include/nodes/pathnodes.h              |   2 +
 src/include/optimizer/optimizer.h          |   6 +
 src/include/utils/guc_hooks.h              |   5 +
 src/test/regress/expected/create_index.out | 293 +++++++++++++++++++++
 src/test/regress/sql/create_index.sql      | 150 +++++++++++
 8 files changed, 588 insertions(+)

diff --git a/doc/src/sgml/config.sgml b/doc/src/sgml/config.sgml
index 0aec11f443..789f286218 100644
--- a/doc/src/sgml/config.sgml
+++ b/doc/src/sgml/config.sgml
@@ -6375,6 +6375,24 @@ SELECT * FROM parent WHERE key = 2400;
       </listitem>
      </varlistentry>
 
+     <varlistentry id="guc-disabled-indexes" xreflabel="disabled_indexes">
+      <term><varname>disabled_indexes</varname> (<type>string</type>)
+      <indexterm>
+       <primary><varname>disabled_indexes</varname> configuration parameter</primary>
+      </indexterm>
+      </term>
+      <listitem>
+       <para>
+        Specifies a comma-separated list of index names that should be ignored
+        by the query planner. This allows for temporarily disabling specific
+        indexes without needing to drop them or rebuild them when enabling.
+        This can be useful for testing query performance with and without
+        certain indexes. It is a session-level parameter, allowing for easily managing
+        the list of disabled indexes.
+       </para>
+      </listitem>
+     </varlistentry>
+
      </variablelist>
     </sect2>
    </sect1>
diff --git a/src/backend/optimizer/util/plancat.c b/src/backend/optimizer/util/plancat.c
index b913f91ff0..04d9313116 100644
--- a/src/backend/optimizer/util/plancat.c
+++ b/src/backend/optimizer/util/plancat.c
@@ -47,14 +47,18 @@
 #include "storage/bufmgr.h"
 #include "tcop/tcopprot.h"
 #include "utils/builtins.h"
+#include "utils/guc_hooks.h"
 #include "utils/lsyscache.h"
 #include "utils/partcache.h"
+#include "utils/plancache.h"
 #include "utils/rel.h"
 #include "utils/snapmgr.h"
 #include "utils/syscache.h"
+#include "utils/varlena.h"
 
 /* GUC parameter */
 int			constraint_exclusion = CONSTRAINT_EXCLUSION_PARTITION;
+char			*disabled_indexes = "";
 
 /* Hook for plugins to get control in get_relation_info() */
 get_relation_info_hook_type get_relation_info_hook = NULL;
@@ -295,6 +299,21 @@ get_relation_info(PlannerInfo *root, Oid relationObjectId, bool inhparent,
 			info->opcintype = (Oid *) palloc(sizeof(Oid) * nkeycolumns);
 			info->canreturn = (bool *) palloc(sizeof(bool) * ncolumns);
 
+			/*
+			 * Skip disabled indexes all together, as they should not be considered
+			 * for query planning. This builds the data structure for the planner's
+			 * use and we make it part of IndexOptInfo since the index is already open.
+			 * We also free the memory and close the relation before continuing
+			 * to the next index.
+			 */
+			info->isdisabled = is_index_disabled(RelationGetRelationName(indexRelation));
+			if (info->isdisabled)
+			{
+				pfree(info);
+				index_close(indexRelation, NoLock);
+				continue;
+			}
+
 			for (i = 0; i < ncolumns; i++)
 			{
 				info->indexkeys[i] = index->indkey.values[i];
@@ -2596,3 +2615,86 @@ set_baserel_partition_constraint(Relation relation, RelOptInfo *rel)
 		rel->partition_qual = partconstr;
 	}
 }
+
+/*
+ * is_index_disabled
+ * Checks if the given index is in the list of disabled indexes.
+ */
+bool
+is_index_disabled(const char *indexName)
+{
+	List	   *namelist;
+	ListCell   *l;
+	char	   *rawstring;
+	bool		result = false;
+
+	if (disabled_indexes == NULL || disabled_indexes[0] == '\0' || indexName == NULL)
+		return false;
+
+	rawstring = pstrdup(disabled_indexes);
+
+	if (!SplitIdentifierString(rawstring, ',', &namelist))
+	{
+		pfree(rawstring);
+		list_free(namelist);
+		return false;
+	}
+
+	foreach(l, namelist)
+	{
+		if (strcmp(indexName, (char *) lfirst(l)) == 0)
+		{
+			result = true;
+			break;
+		}
+	}
+
+	list_free(namelist);
+	pfree(rawstring);
+
+	return result;
+}
+
+/*
+ * assign_disabled_indexes
+ * GUC assign_hook for "disabled_indexes" GUC variable.
+ * Updates the disabled_indexes value and resets the plan cache if the value has changed.
+ */
+void
+assign_disabled_indexes(const char *newval, void *extra)
+{
+	if (disabled_indexes == NULL || strcmp(disabled_indexes, newval) != 0)
+	{
+		disabled_indexes = guc_strdup(ERROR, newval);
+		ResetPlanCache();
+	}
+}
+
+/*
+ * check_disabled_indexes
+ * GUC check_hook for "disabled_indexes" GUC variable.
+ * Validates the new value for disabled_indexes.
+ */
+bool
+check_disabled_indexes(char **newval, void **extra, GucSource source)
+{
+	List	   *namelist = NIL;
+	char	   *rawstring;
+
+	if (*newval == NULL || strcmp(*newval, "") == 0)
+		return true;
+
+	rawstring = pstrdup(*newval);
+
+	if (!SplitIdentifierString(rawstring, ',', &namelist))
+	{
+		pfree(rawstring);
+		list_free(namelist);
+		return false;
+	}
+
+	pfree(rawstring);
+	list_free(namelist);
+
+	return true;
+}
diff --git a/src/backend/utils/misc/guc_tables.c b/src/backend/utils/misc/guc_tables.c
index 686309db58..3f19af566c 100644
--- a/src/backend/utils/misc/guc_tables.c
+++ b/src/backend/utils/misc/guc_tables.c
@@ -4783,6 +4783,18 @@ struct config_string ConfigureNamesString[] =
 		check_restrict_nonsystem_relation_kind, assign_restrict_nonsystem_relation_kind, NULL
 	},
 
+	{
+		{"disabled_indexes", PGC_USERSET, QUERY_TUNING_OTHER,
+			gettext_noop("Sets the list of indexes to be disabled for query planning."),
+			NULL,
+			GUC_LIST_INPUT | GUC_NOT_IN_SAMPLE | GUC_EXPLAIN
+		},
+		&disabled_indexes,
+		"",
+		check_disabled_indexes, assign_disabled_indexes, NULL
+	},
+
+
 	/* End-of-list marker */
 	{
 		{NULL, 0, 0, NULL, NULL}, NULL, NULL, NULL, NULL, NULL
diff --git a/src/include/nodes/pathnodes.h b/src/include/nodes/pathnodes.h
index 07e2415398..d65fad121c 100644
--- a/src/include/nodes/pathnodes.h
+++ b/src/include/nodes/pathnodes.h
@@ -1207,6 +1207,8 @@ struct IndexOptInfo
 	/* AM's cost estimator */
 	/* Rather than include amapi.h here, we declare amcostestimate like this */
 	void		(*amcostestimate) () pg_node_attr(read_write_ignore);
+	/* true if this index is asked to be disabled */
+	bool		isdisabled;
 };
 
 /*
diff --git a/src/include/optimizer/optimizer.h b/src/include/optimizer/optimizer.h
index 93e3dc719d..f008ff98af 100644
--- a/src/include/optimizer/optimizer.h
+++ b/src/include/optimizer/optimizer.h
@@ -203,4 +203,10 @@ extern List *pull_var_clause(Node *node, int flags);
 extern Node *flatten_join_alias_vars(PlannerInfo *root, Query *query, Node *node);
 extern Node *flatten_group_exprs(PlannerInfo *root, Query *query, Node *node);
 
+/*
+ * GUC variable for specifying indexes to be ignored by the query planner.
+ * Contains a comma-separated list of index names.
+ */
+extern PGDLLIMPORT char *disabled_indexes;
+
 #endif							/* OPTIMIZER_H */
diff --git a/src/include/utils/guc_hooks.h b/src/include/utils/guc_hooks.h
index 5813dba0a2..4b8172fa00 100644
--- a/src/include/utils/guc_hooks.h
+++ b/src/include/utils/guc_hooks.h
@@ -175,4 +175,9 @@ extern bool check_synchronized_standby_slots(char **newval, void **extra,
 											 GucSource source);
 extern void assign_synchronized_standby_slots(const char *newval, void *extra);
 
+
+extern void assign_disabled_indexes(const char *newval, void *extra);
+extern bool is_index_disabled(const char *indexName);
+extern bool check_disabled_indexes(char **newval, void **extra, GucSource source);
+
 #endif							/* GUC_HOOKS_H */
diff --git a/src/test/regress/expected/create_index.out b/src/test/regress/expected/create_index.out
index d3358dfc39..4f0b0eb59d 100644
--- a/src/test/regress/expected/create_index.out
+++ b/src/test/regress/expected/create_index.out
@@ -2965,6 +2965,299 @@ ERROR:  REINDEX SCHEMA cannot run inside a transaction block
 END;
 -- concurrently
 REINDEX SCHEMA CONCURRENTLY schema_to_reindex;
+-- Test enabling/disabling of indexes
+-- Create tables
+CREATE TABLE basic_table (id serial PRIMARY KEY, value integer, text_col text);
+CREATE TABLE io_table (id serial PRIMARY KEY, value integer, category char(1));
+CREATE TABLE join_table (id serial PRIMARY KEY, basic_id integer, io_id integer);
+-- Create various types of indexes
+CREATE INDEX basic_value_idx ON basic_table (value);
+CREATE INDEX io_value_idx ON io_table (value);
+CREATE INDEX basic_multi_col_idx ON basic_table (value, text_col);
+CREATE INDEX io_partial_idx ON io_table (value) WHERE category = 'A';
+CREATE INDEX basic_expr_idx ON basic_table ((lower(text_col)));
+CREATE INDEX join_idx ON join_table (basic_id, io_id);
+-- Insert sample data
+INSERT INTO basic_table (value, text_col)
+SELECT i, 'Text ' || i FROM generate_series(1, 10000) i;
+INSERT INTO io_table (value, category)
+SELECT i, CASE WHEN i % 2 = 0 THEN 'A' ELSE 'B' END
+FROM generate_series(1, 10000) i;
+INSERT INTO join_table (basic_id, io_id)
+SELECT i % 10000 + 1, i % 10000 + 1 FROM generate_series(1, 20000) i;
+ANALYZE basic_table, io_table, join_table;
+-- Test queries with all indexes enabled
+EXPLAIN (COSTS OFF) SELECT * FROM basic_table WHERE value = 50;
+                     QUERY PLAN                      
+-----------------------------------------------------
+ Index Scan using basic_multi_col_idx on basic_table
+   Index Cond: (value = 50)
+(2 rows)
+
+EXPLAIN (COSTS OFF) SELECT * FROM io_table WHERE value BETWEEN 40 AND 60 AND category = 'A';
+                   QUERY PLAN                    
+-------------------------------------------------
+ Index Scan using io_partial_idx on io_table
+   Index Cond: ((value >= 40) AND (value <= 60))
+(2 rows)
+
+EXPLAIN (COSTS OFF) SELECT * FROM basic_table WHERE lower(text_col) = 'text 100';
+                     QUERY PLAN                     
+----------------------------------------------------
+ Index Scan using basic_expr_idx on basic_table
+   Index Cond: (lower(text_col) = 'text 100'::text)
+(2 rows)
+
+EXPLAIN (COSTS OFF) SELECT * FROM basic_table b JOIN join_table j ON b.id = j.basic_id WHERE b.value = 500;
+                         QUERY PLAN                          
+-------------------------------------------------------------
+ Nested Loop
+   ->  Index Scan using basic_multi_col_idx on basic_table b
+         Index Cond: (value = 500)
+   ->  Bitmap Heap Scan on join_table j
+         Recheck Cond: (b.id = basic_id)
+         ->  Bitmap Index Scan on join_idx
+               Index Cond: (basic_id = b.id)
+(7 rows)
+
+-- Disable single-column indexes
+SET disabled_indexes = 'basic_value_idx,io_value_idx';
+-- Test queries with single-column indexes disabled
+EXPLAIN (COSTS OFF) SELECT * FROM basic_table WHERE value = 50;
+                     QUERY PLAN                      
+-----------------------------------------------------
+ Index Scan using basic_multi_col_idx on basic_table
+   Index Cond: (value = 50)
+(2 rows)
+
+EXPLAIN (COSTS OFF) SELECT * FROM io_table WHERE value BETWEEN 40 AND 60 AND category = 'A';
+                   QUERY PLAN                    
+-------------------------------------------------
+ Index Scan using io_partial_idx on io_table
+   Index Cond: ((value >= 40) AND (value <= 60))
+(2 rows)
+
+-- Disable all custom indexes
+SET disabled_indexes = 'basic_value_idx,io_value_idx,basic_multi_col_idx,io_partial_idx,basic_expr_idx,join_idx';
+-- Test queries with all custom indexes disabled
+EXPLAIN (COSTS OFF) SELECT * FROM basic_table WHERE value = 50;
+       QUERY PLAN        
+-------------------------
+ Seq Scan on basic_table
+   Filter: (value = 50)
+(2 rows)
+
+EXPLAIN (COSTS OFF) SELECT * FROM io_table WHERE value BETWEEN 40 AND 60 AND category = 'A';
+                                QUERY PLAN                                
+--------------------------------------------------------------------------
+ Seq Scan on io_table
+   Filter: ((value >= 40) AND (value <= 60) AND (category = 'A'::bpchar))
+(2 rows)
+
+EXPLAIN (COSTS OFF) SELECT * FROM basic_table WHERE lower(text_col) = 'text 100';
+                   QUERY PLAN                   
+------------------------------------------------
+ Seq Scan on basic_table
+   Filter: (lower(text_col) = 'text 100'::text)
+(2 rows)
+
+EXPLAIN (COSTS OFF) SELECT * FROM basic_table b JOIN join_table j ON b.id = j.basic_id WHERE b.value = 500;
+              QUERY PLAN               
+---------------------------------------
+ Hash Join
+   Hash Cond: (j.basic_id = b.id)
+   ->  Seq Scan on join_table j
+   ->  Hash
+         ->  Seq Scan on basic_table b
+               Filter: (value = 500)
+(6 rows)
+
+-- Enable all indexes again
+SET disabled_indexes = '';
+-- Test with a non-existent index name
+SET disabled_indexes = 'non_existent_idx';
+EXPLAIN (COSTS OFF) SELECT * FROM basic_table WHERE value = 50;
+                     QUERY PLAN                      
+-----------------------------------------------------
+ Index Scan using basic_multi_col_idx on basic_table
+   Index Cond: (value = 50)
+(2 rows)
+
+-- Test disabled indexes with mixed case index names
+CREATE INDEX Mixed_Case_Idx ON basic_table (value);
+SET disabled_indexes = 'Mixed_Case_Idx';
+EXPLAIN (COSTS OFF) SELECT * FROM basic_table WHERE value = 50;
+                     QUERY PLAN                      
+-----------------------------------------------------
+ Index Scan using basic_multi_col_idx on basic_table
+   Index Cond: (value = 50)
+(2 rows)
+
+-- Clean up
+DROP TABLE basic_table, io_table, join_table;
+-- Test more complex index types
+CREATE TABLE multi_purpose (
+    id serial PRIMARY KEY,
+    value integer,
+    text_col text,
+    ts_col tsvector,
+    point_col point
+);
+CREATE TABLE range_table (
+    id serial PRIMARY KEY,
+    range_col int4range
+);
+CREATE INDEX multi_expr_idx ON multi_purpose ((value % 10));
+CREATE INDEX multi_covering_idx ON multi_purpose (value) INCLUDE (text_col);
+CREATE INDEX multi_ts_idx ON multi_purpose USING GIN (ts_col);
+CREATE INDEX multi_point_idx ON multi_purpose USING GIST (point_col);
+CREATE INDEX range_idx ON range_table USING GIST (range_col);
+INSERT INTO multi_purpose (value, text_col, ts_col, point_col)
+SELECT
+    i,
+    'Text ' || i,
+    to_tsvector('english', 'Text ' || i || ' is a sample'),
+    point(i % 100, i % 100)
+FROM generate_series(1, 10000) i;
+INSERT INTO range_table (range_col)
+SELECT int4range(i, i+10) FROM generate_series(1, 1000) i;
+ANALYZE multi_purpose, range_table;
+-- Test queries with all indexes enabled
+EXPLAIN (COSTS OFF) SELECT * FROM multi_purpose WHERE value % 10 = 5;
+                QUERY PLAN                 
+-------------------------------------------
+ Bitmap Heap Scan on multi_purpose
+   Recheck Cond: ((value % 10) = 5)
+   ->  Bitmap Index Scan on multi_expr_idx
+         Index Cond: ((value % 10) = 5)
+(4 rows)
+
+EXPLAIN (COSTS OFF) SELECT * FROM multi_purpose WHERE to_tsquery('english', 'text & sample') @@ ts_col;
+                      QUERY PLAN                       
+-------------------------------------------------------
+ Seq Scan on multi_purpose
+   Filter: ('''text'' & ''sampl'''::tsquery @@ ts_col)
+(2 rows)
+
+EXPLAIN (COSTS OFF) SELECT * FROM multi_purpose WHERE point_col <@ box '((0,0),(50,50))';
+                       QUERY PLAN                        
+---------------------------------------------------------
+ Bitmap Heap Scan on multi_purpose
+   Recheck Cond: (point_col <@ '(50,50),(0,0)'::box)
+   ->  Bitmap Index Scan on multi_point_idx
+         Index Cond: (point_col <@ '(50,50),(0,0)'::box)
+(4 rows)
+
+EXPLAIN (COSTS OFF) SELECT * FROM range_table WHERE range_col && int4range(5, 15);
+                       QUERY PLAN                       
+--------------------------------------------------------
+ Bitmap Heap Scan on range_table
+   Recheck Cond: (range_col && '[5,15)'::int4range)
+   ->  Bitmap Index Scan on range_idx
+         Index Cond: (range_col && '[5,15)'::int4range)
+(4 rows)
+
+-- Disable indexes
+SET disabled_indexes = 'multi_expr_idx,multi_covering_idx,multi_ts_idx,multi_point_idx,range_idx';
+-- Test queries with indexes disabled
+EXPLAIN (COSTS OFF) SELECT * FROM multi_purpose WHERE value % 10 = 5;
+          QUERY PLAN          
+------------------------------
+ Seq Scan on multi_purpose
+   Filter: ((value % 10) = 5)
+(2 rows)
+
+EXPLAIN (COSTS OFF) SELECT * FROM multi_purpose WHERE to_tsquery('english', 'text & sample') @@ ts_col;
+                      QUERY PLAN                       
+-------------------------------------------------------
+ Seq Scan on multi_purpose
+   Filter: ('''text'' & ''sampl'''::tsquery @@ ts_col)
+(2 rows)
+
+EXPLAIN (COSTS OFF) SELECT * FROM multi_purpose WHERE point_col <@ box '((0,0),(50,50))';
+                  QUERY PLAN                   
+-----------------------------------------------
+ Seq Scan on multi_purpose
+   Filter: (point_col <@ '(50,50),(0,0)'::box)
+(2 rows)
+
+EXPLAIN (COSTS OFF) SELECT * FROM range_table WHERE range_col && int4range(5, 15);
+                  QUERY PLAN                  
+----------------------------------------------
+ Seq Scan on range_table
+   Filter: (range_col && '[5,15)'::int4range)
+(2 rows)
+
+-- Enable all indexes again
+SET disabled_indexes = '';
+-- Clean up
+DROP TABLE multi_purpose, range_table;
+-- Test disabled indexes with unique constraints
+CREATE TABLE dual_index_test (id int, value text);
+CREATE UNIQUE INDEX uniq_dual_index_test_id_idx ON dual_index_test (id);
+CREATE INDEX dual_index_test_value_idx ON dual_index_test (value);
+INSERT INTO dual_index_test VALUES (1, 'one'), (2, 'two'), (3, 'three');
+-- Test with both indexes enabled
+EXPLAIN (COSTS OFF) SELECT * FROM dual_index_test WHERE id = 1;
+                           QUERY PLAN                            
+-----------------------------------------------------------------
+ Index Scan using uniq_dual_index_test_id_idx on dual_index_test
+   Index Cond: (id = 1)
+(2 rows)
+
+EXPLAIN (COSTS OFF) SELECT * FROM dual_index_test WHERE value = 'two';
+                      QUERY PLAN                      
+------------------------------------------------------
+ Bitmap Heap Scan on dual_index_test
+   Recheck Cond: (value = 'two'::text)
+   ->  Bitmap Index Scan on dual_index_test_value_idx
+         Index Cond: (value = 'two'::text)
+(4 rows)
+
+-- Disable the unique index
+SET disabled_indexes TO 'uniq_dual_index_test_id_idx';
+-- Try to insert a duplicate value
+INSERT INTO dual_index_test VALUES (1, 'duplicate');
+ERROR:  duplicate key value violates unique constraint "uniq_dual_index_test_id_idx"
+DETAIL:  Key (id)=(1) already exists.
+-- Check query plans
+EXPLAIN (COSTS OFF) SELECT * FROM dual_index_test WHERE id = 1;
+         QUERY PLAN          
+-----------------------------
+ Seq Scan on dual_index_test
+   Filter: (id = 1)
+(2 rows)
+
+EXPLAIN (COSTS OFF) SELECT * FROM dual_index_test WHERE value = 'two';
+                      QUERY PLAN                      
+------------------------------------------------------
+ Bitmap Heap Scan on dual_index_test
+   Recheck Cond: (value = 'two'::text)
+   ->  Bitmap Index Scan on dual_index_test_value_idx
+         Index Cond: (value = 'two'::text)
+(4 rows)
+
+-- Disable both indexes
+SET disabled_indexes TO 'uniq_dual_index_test_id_idx,dual_index_test_value_idx';
+-- Check query plans again
+EXPLAIN (COSTS OFF) SELECT * FROM dual_index_test WHERE id = 1;
+         QUERY PLAN          
+-----------------------------
+ Seq Scan on dual_index_test
+   Filter: (id = 1)
+(2 rows)
+
+EXPLAIN (COSTS OFF) SELECT * FROM dual_index_test WHERE value = 'two';
+           QUERY PLAN            
+---------------------------------
+ Seq Scan on dual_index_test
+   Filter: (value = 'two'::text)
+(2 rows)
+
+-- Reset disabled_indexes
+SET disabled_indexes TO '';
+-- Clean up
+DROP TABLE dual_index_test;
 -- Failure for unauthorized user
 CREATE ROLE regress_reindexuser NOLOGIN;
 SET SESSION ROLE regress_reindexuser;
diff --git a/src/test/regress/sql/create_index.sql b/src/test/regress/sql/create_index.sql
index fe162cc7c3..a21f855828 100644
--- a/src/test/regress/sql/create_index.sql
+++ b/src/test/regress/sql/create_index.sql
@@ -1297,6 +1297,156 @@ END;
 -- concurrently
 REINDEX SCHEMA CONCURRENTLY schema_to_reindex;
 
+-- Test enabling/disabling of indexes
+-- Create tables
+CREATE TABLE basic_table (id serial PRIMARY KEY, value integer, text_col text);
+CREATE TABLE io_table (id serial PRIMARY KEY, value integer, category char(1));
+CREATE TABLE join_table (id serial PRIMARY KEY, basic_id integer, io_id integer);
+
+-- Create various types of indexes
+CREATE INDEX basic_value_idx ON basic_table (value);
+CREATE INDEX io_value_idx ON io_table (value);
+CREATE INDEX basic_multi_col_idx ON basic_table (value, text_col);
+CREATE INDEX io_partial_idx ON io_table (value) WHERE category = 'A';
+CREATE INDEX basic_expr_idx ON basic_table ((lower(text_col)));
+CREATE INDEX join_idx ON join_table (basic_id, io_id);
+
+-- Insert sample data
+INSERT INTO basic_table (value, text_col)
+SELECT i, 'Text ' || i FROM generate_series(1, 10000) i;
+INSERT INTO io_table (value, category)
+SELECT i, CASE WHEN i % 2 = 0 THEN 'A' ELSE 'B' END
+FROM generate_series(1, 10000) i;
+INSERT INTO join_table (basic_id, io_id)
+SELECT i % 10000 + 1, i % 10000 + 1 FROM generate_series(1, 20000) i;
+
+ANALYZE basic_table, io_table, join_table;
+
+-- Test queries with all indexes enabled
+EXPLAIN (COSTS OFF) SELECT * FROM basic_table WHERE value = 50;
+EXPLAIN (COSTS OFF) SELECT * FROM io_table WHERE value BETWEEN 40 AND 60 AND category = 'A';
+EXPLAIN (COSTS OFF) SELECT * FROM basic_table WHERE lower(text_col) = 'text 100';
+EXPLAIN (COSTS OFF) SELECT * FROM basic_table b JOIN join_table j ON b.id = j.basic_id WHERE b.value = 500;
+
+-- Disable single-column indexes
+SET disabled_indexes = 'basic_value_idx,io_value_idx';
+
+-- Test queries with single-column indexes disabled
+EXPLAIN (COSTS OFF) SELECT * FROM basic_table WHERE value = 50;
+EXPLAIN (COSTS OFF) SELECT * FROM io_table WHERE value BETWEEN 40 AND 60 AND category = 'A';
+
+-- Disable all custom indexes
+SET disabled_indexes = 'basic_value_idx,io_value_idx,basic_multi_col_idx,io_partial_idx,basic_expr_idx,join_idx';
+
+-- Test queries with all custom indexes disabled
+EXPLAIN (COSTS OFF) SELECT * FROM basic_table WHERE value = 50;
+EXPLAIN (COSTS OFF) SELECT * FROM io_table WHERE value BETWEEN 40 AND 60 AND category = 'A';
+EXPLAIN (COSTS OFF) SELECT * FROM basic_table WHERE lower(text_col) = 'text 100';
+EXPLAIN (COSTS OFF) SELECT * FROM basic_table b JOIN join_table j ON b.id = j.basic_id WHERE b.value = 500;
+
+-- Enable all indexes again
+SET disabled_indexes = '';
+
+-- Test with a non-existent index name
+SET disabled_indexes = 'non_existent_idx';
+EXPLAIN (COSTS OFF) SELECT * FROM basic_table WHERE value = 50;
+
+-- Test disabled indexes with mixed case index names
+CREATE INDEX Mixed_Case_Idx ON basic_table (value);
+SET disabled_indexes = 'Mixed_Case_Idx';
+EXPLAIN (COSTS OFF) SELECT * FROM basic_table WHERE value = 50;
+
+-- Clean up
+DROP TABLE basic_table, io_table, join_table;
+
+-- Test more complex index types
+CREATE TABLE multi_purpose (
+    id serial PRIMARY KEY,
+    value integer,
+    text_col text,
+    ts_col tsvector,
+    point_col point
+);
+
+CREATE TABLE range_table (
+    id serial PRIMARY KEY,
+    range_col int4range
+);
+
+CREATE INDEX multi_expr_idx ON multi_purpose ((value % 10));
+CREATE INDEX multi_covering_idx ON multi_purpose (value) INCLUDE (text_col);
+CREATE INDEX multi_ts_idx ON multi_purpose USING GIN (ts_col);
+CREATE INDEX multi_point_idx ON multi_purpose USING GIST (point_col);
+CREATE INDEX range_idx ON range_table USING GIST (range_col);
+
+INSERT INTO multi_purpose (value, text_col, ts_col, point_col)
+SELECT
+    i,
+    'Text ' || i,
+    to_tsvector('english', 'Text ' || i || ' is a sample'),
+    point(i % 100, i % 100)
+FROM generate_series(1, 10000) i;
+
+INSERT INTO range_table (range_col)
+SELECT int4range(i, i+10) FROM generate_series(1, 1000) i;
+
+ANALYZE multi_purpose, range_table;
+
+-- Test queries with all indexes enabled
+EXPLAIN (COSTS OFF) SELECT * FROM multi_purpose WHERE value % 10 = 5;
+EXPLAIN (COSTS OFF) SELECT * FROM multi_purpose WHERE to_tsquery('english', 'text & sample') @@ ts_col;
+EXPLAIN (COSTS OFF) SELECT * FROM multi_purpose WHERE point_col <@ box '((0,0),(50,50))';
+EXPLAIN (COSTS OFF) SELECT * FROM range_table WHERE range_col && int4range(5, 15);
+
+-- Disable indexes
+SET disabled_indexes = 'multi_expr_idx,multi_covering_idx,multi_ts_idx,multi_point_idx,range_idx';
+
+-- Test queries with indexes disabled
+EXPLAIN (COSTS OFF) SELECT * FROM multi_purpose WHERE value % 10 = 5;
+EXPLAIN (COSTS OFF) SELECT * FROM multi_purpose WHERE to_tsquery('english', 'text & sample') @@ ts_col;
+EXPLAIN (COSTS OFF) SELECT * FROM multi_purpose WHERE point_col <@ box '((0,0),(50,50))';
+EXPLAIN (COSTS OFF) SELECT * FROM range_table WHERE range_col && int4range(5, 15);
+
+-- Enable all indexes again
+SET disabled_indexes = '';
+
+-- Clean up
+DROP TABLE multi_purpose, range_table;
+
+-- Test disabled indexes with unique constraints
+CREATE TABLE dual_index_test (id int, value text);
+CREATE UNIQUE INDEX uniq_dual_index_test_id_idx ON dual_index_test (id);
+CREATE INDEX dual_index_test_value_idx ON dual_index_test (value);
+
+INSERT INTO dual_index_test VALUES (1, 'one'), (2, 'two'), (3, 'three');
+
+-- Test with both indexes enabled
+EXPLAIN (COSTS OFF) SELECT * FROM dual_index_test WHERE id = 1;
+EXPLAIN (COSTS OFF) SELECT * FROM dual_index_test WHERE value = 'two';
+
+-- Disable the unique index
+SET disabled_indexes TO 'uniq_dual_index_test_id_idx';
+
+-- Try to insert a duplicate value
+INSERT INTO dual_index_test VALUES (1, 'duplicate');
+
+-- Check query plans
+EXPLAIN (COSTS OFF) SELECT * FROM dual_index_test WHERE id = 1;
+EXPLAIN (COSTS OFF) SELECT * FROM dual_index_test WHERE value = 'two';
+
+-- Disable both indexes
+SET disabled_indexes TO 'uniq_dual_index_test_id_idx,dual_index_test_value_idx';
+
+-- Check query plans again
+EXPLAIN (COSTS OFF) SELECT * FROM dual_index_test WHERE id = 1;
+EXPLAIN (COSTS OFF) SELECT * FROM dual_index_test WHERE value = 'two';
+
+-- Reset disabled_indexes
+SET disabled_indexes TO '';
+
+-- Clean up
+DROP TABLE dual_index_test;
+
 -- Failure for unauthorized user
 CREATE ROLE regress_reindexuser NOLOGIN;
 SET SESSION ROLE regress_reindexuser;
-- 
2.37.1 (Apple Git-137.1)

#26Shayon Mukherjee
shayonj@gmail.com
In reply to: Shayon Mukherjee (#25)
Re: Proposal to Enable/Disable Index using ALTER INDEX

Hello,

Also added this as a post in Commit Fest [0]https://commitfest.postgresql.org/50/5274/

[0]: https://commitfest.postgresql.org/50/5274/

Thank you
Shayon

Show quoted text

On Sep 26, 2024, at 1:39 PM, Shayon Mukherjee <shayonj@gmail.com> wrote:

Hello,

I am back with a PATCH :). Thanks to everyone in the threads for all the helpful discussions.

This proposal is for a PATCH to introduce a GUC variable to disable specific indexes during query planning.

This is an alternative approach to the previous PATCH I had proposed and is improved upon after some of the recent discussions in the thread. The PATCH contains the relevant changes, regression tests, and documentation.

I went with the GUC approach to introduce a way for a user to disable indexes during query planning over dedicated SQL Grammar and introducing the `isenabled` attribute in `pg_index` for the following reasons:

- Inspired by the discussions brought in earlier about this setting being something that unprivileged users can benefit from versus an ALTER statement.
- A GUC variable felt more closely aligned with the query tuning purpose, which this feature would serve, over index maintenance, the state of which is more closely reflected in `pg_index`.

Implementation details:

The patch introduces a new GUC parameter `disabled_indexes` that allows users to specify a comma-separated list of indexes to be ignored during query planning. Key aspects:

- Adds a new `isdisabled` attribute to the `IndexOptInfo` structure.
- Modifies `get_relation_info` in `plancat.c` to skip disabled indexes entirely, thus reducing the number of places we need to check if an index is disabled or not.
- Implements GUC hooks for parameter validation and assignment.
- Resets the plan cache when the `disabled_indexes` list is modified through `ResetPlanCache()`

I chose to modify the logic within `get_relation_info` as compared to, say, reducing the cost to make the planner not consider an index during planning, mostly to keep the number of changes being introduced to a minimum and also the logic itself being self-contained and easier to under perhaps (?).

As mentioned before, this does not impact the building of the index. That still happens.

I have added regression tests for:

- Basic single-column and multi-column indexes
- Partial indexes
- Expression indexes
- Join indexes
- GIN and GiST indexes
- Covering indexes
- Range indexes
- Unique indexes and constraints

I'd love to hear any feedback on the proposed PATCH and also the overall approach.
<v1-0001-Ability-to-enable-disable-indexes-through-GUC.patch>

On Sep 24, 2024, at 9:19 AM, Shayon Mukherjee <shayonj@gmail.com> wrote:

--
Kind Regards,
Shayon Mukherjee
<v1-0001-Proof-of-Concept-Ability-to-enable-disable-indexe.patch>

#27Robert Haas
robertmhaas@gmail.com
In reply to: Peter Eisentraut (#14)
Re: Proposal to Enable/Disable Index using ALTER INDEX

On Mon, Sep 23, 2024 at 11:14 AM Peter Eisentraut <peter@eisentraut.org> wrote:

I think a better approach would be to make the list of disabled indexes
a GUC setting, which would then internally have an effect similar to
enable_indexscan, meaning it would make the listed indexes unattractive
to the planner.

This seems better than the proposed DDL command, because you'd be able
to use this per-session, instead of forcing a global state, and even
unprivileged users could use it.

(I think we have had proposals like this before, but I can't find the
discussion I'm thinking of right now.)

I feel like a given user could want either one of these things. If
you've discovered that a certain index is causing your production
application to pick the wrong index, disabling it and thereby
affecting all backends is what you want. If you're trying to
experiment with different query plans without changing anything for
other backends, being able to set some session-local state is better.
I don't understand the argument that one of these is categorically
better than the other.

--
Robert Haas
EDB: http://www.enterprisedb.com

#28Shayon Mukherjee
shayonj@gmail.com
In reply to: Robert Haas (#27)
Re: Proposal to Enable/Disable Index using ALTER INDEX

On Oct 7, 2024, at 4:52 PM, Robert Haas <robertmhaas@gmail.com> wrote:

On Mon, Sep 23, 2024 at 11:14 AM Peter Eisentraut <peter@eisentraut.org> wrote:

I think a better approach would be to make the list of disabled indexes
a GUC setting, which would then internally have an effect similar to
enable_indexscan, meaning it would make the listed indexes unattractive
to the planner.

This seems better than the proposed DDL command, because you'd be able
to use this per-session, instead of forcing a global state, and even
unprivileged users could use it.

(I think we have had proposals like this before, but I can't find the
discussion I'm thinking of right now.)

I feel like a given user could want either one of these things. If
you've discovered that a certain index is causing your production
application to pick the wrong index, disabling it and thereby
affecting all backends is what you want. If you're trying to
experiment with different query plans without changing anything for
other backends, being able to set some session-local state is better.
I don't understand the argument that one of these is categorically
better than the other.

Makes sense to me and it’s something I am somewhat split on as well. I suppose with a GUC you can still do some thing like

ALTER USER foobar SET disabled_indexes to ‘idx_test_table_id’

[thinking…] This way all new sessions will start to not consider the index when query planning. Of course it does not help existing sessions, so one may need to kill those backends, which could be heavy handed.

Both these options clearly serve slightly different purposes with good pros and I am currently thinking if GUC is that good middle ground solution.

Curious if someone has a stronger opinion on which one of these might make more sense perhaps :-D.

[thinking…] Unless - we try to do support both a GUC and the ALTER INDEX ENABLE/DISABLE grammar + isdisabled attribute on pg_index?

I can see that both implementations (GUC and the new attribute on pg_index via ALTER) have the primary logic managed by `get_relation_info` in `plancat.c`. Here, we set `isdisabled` (new attribute) on `IndexOptInfo` and compare it against `disabled_indexes` in the GUC (from the previous GUC patch). Similarly, for `pg_index`, which is already open in `get_relation_info`, we can read from `pg_index.isdisabled` and accordingly update `IndexOptInfo.isdisabled`.

[0]: /messages/by-id/6CE345C1-6FFD-4E4C-8775-45DA659C57CF@gmail.com

Thanks
Shayon

#29David Rowley
dgrowleyml@gmail.com
In reply to: Shayon Mukherjee (#28)
Re: Proposal to Enable/Disable Index using ALTER INDEX

On Wed, 9 Oct 2024 at 20:07, Shayon Mukherjee <shayonj@gmail.com> wrote:

[thinking…] Unless - we try to do support both a GUC and the ALTER INDEX ENABLE/DISABLE grammar + isdisabled attribute on pg_index?

I just wanted to explain my point of view on this. This is my opinion
and is by no means authoritative.

I was interested in this patch when you proposed it as an ALTER INDEX
option. I know other committers seem interested, but I personally
don't have any interest in the GUC option. I think the reason I
dislike it is that it's yet another not even half-baked take on
planner hints (the other one being enable* GUCs). I often thought that
if we ever did planner hints that it would be great to have multiple
ways to specify the hints. Ordinarily, I'd expect some special comment
type as the primary method to specify hints, but equally, it would be
nice to be able to specify them in other ways. e.g. a GUC to have them
apply to more than just 1 query. Useful for things such as "don't use
index X".

Now, I'm not suggesting you go off and code up planner hints. That's a
huge project. I'm just concerned that we've already got a fair bit of
cruft that will be left remaining if we ever get core planner hints
and a disabled_indexes GUC will just add to that. I don't feel like
the ALTER INDEX method would be leftover cruft from us gaining core
planner hints. Others might feel differently on that one. I feel the
ALTER INDEX option is less controversial.

I'll also stand by what I said earlier on this thread. If PeterG gets
index skip scans done for PG18, then it's likely there's going to be
lots of users considering if they still need a certain index or not
after upgrading to PG18.

David

#30Robert Haas
robertmhaas@gmail.com
In reply to: David Rowley (#29)
Re: Proposal to Enable/Disable Index using ALTER INDEX

On Wed, Oct 9, 2024 at 4:19 AM David Rowley <dgrowleyml@gmail.com> wrote:

On Wed, 9 Oct 2024 at 20:07, Shayon Mukherjee <shayonj@gmail.com> wrote:

[thinking…] Unless - we try to do support both a GUC and the ALTER INDEX ENABLE/DISABLE grammar + isdisabled attribute on pg_index?

I just wanted to explain my point of view on this. This is my opinion
and is by no means authoritative.

I was interested in this patch when you proposed it as an ALTER INDEX
option. I know other committers seem interested, but I personally
don't have any interest in the GUC option. I think the reason I
dislike it is that it's yet another not even half-baked take on
planner hints (the other one being enable* GUCs). I often thought that
if we ever did planner hints that it would be great to have multiple
ways to specify the hints. Ordinarily, I'd expect some special comment
type as the primary method to specify hints, but equally, it would be
nice to be able to specify them in other ways. e.g. a GUC to have them
apply to more than just 1 query. Useful for things such as "don't use
index X".

+1. A GUC can be done as a contrib module using existing hooks, and I
think that's already been done outside of core, perhaps multiple
times. That certainly doesn't mean we CAN'T add it as an in-core
feature, but I do think "yet another not even half-baked take on
planner hints" is a fair description. What I would personally like to
see is for us to ship one or possibly more than one contrib module
that let people do hint-like things in useful ways, and this could be
a part of that. But I think we need better infrastructure for
controlling the planner behavior first, hence the "allowing extensions
to control planner behavior" thread.

--
Robert Haas
EDB: http://www.enterprisedb.com

#31Vinícius Abrahão
vinnix.bsd@gmail.com
In reply to: Robert Haas (#30)
Re: Proposal to Enable/Disable Index using ALTER INDEX

On Wed, Oct 9, 2024 at 1:41 PM Robert Haas <robertmhaas@gmail.com> wrote:

On Wed, Oct 9, 2024 at 4:19 AM David Rowley <dgrowleyml@gmail.com> wrote:

On Wed, 9 Oct 2024 at 20:07, Shayon Mukherjee <shayonj@gmail.com> wrote:

[thinking…] Unless - we try to do support both a GUC and the ALTER

INDEX ENABLE/DISABLE grammar + isdisabled attribute on pg_index?

I just wanted to explain my point of view on this. This is my opinion
and is by no means authoritative.

I was interested in this patch when you proposed it as an ALTER INDEX
option. I know other committers seem interested, but I personally
don't have any interest in the GUC option. I think the reason I
dislike it is that it's yet another not even half-baked take on
planner hints (the other one being enable* GUCs). I often thought that
if we ever did planner hints that it would be great to have multiple
ways to specify the hints. Ordinarily, I'd expect some special comment
type as the primary method to specify hints, but equally, it would be
nice to be able to specify them in other ways. e.g. a GUC to have them
apply to more than just 1 query. Useful for things such as "don't use
index X".

+1. A GUC can be done as a contrib module using existing hooks, and I
think that's already been done outside of core, perhaps multiple
times. That certainly doesn't mean we CAN'T add it as an in-core
feature, but I do think "yet another not even half-baked take on
planner hints" is a fair description. What I would personally like to
see is for us to ship one or possibly more than one contrib module
that let people do hint-like things in useful ways, and this could be
a part of that. But I think we need better infrastructure for
controlling the planner behavior first, hence the "allowing extensions
to control planner behavior" thread.

What's the strategy here in this discussion?
This topic is older than PostgreSQL itself - everytime WE talk about
so-called "hints" we see procrastination in the name of trademarks.
Lack of definition of what can and can't be done with hooks and what is the
infra-estructural code that is necessary to allow it from core.

Take for example the need of disabling an index. What does it mean
practically and for which component of the code?
You are going to disable the index but not the update of it? Why? Does it
imply that when you are going to re-enable it you are going to recreate it?
So that's more observed from the point of syntax and facilities.
Also distributed into partitions and why not the opposite: the creation of
a global index for all partitions. Also in discussion elsewhere.
Otherwise it will appear that people will need hints and contribs to
"outsource" the main role of what is strategic to the team to companies
elsewhere.

Regards,
Vinícius

#32Shayon Mukherjee
shayonj@gmail.com
In reply to: David Rowley (#29)
Re: Proposal to Enable/Disable Index using ALTER INDEX

Hi David,

Answered below

On Oct 9, 2024, at 9:19 AM, David Rowley <dgrowleyml@gmail.com> wrote:

On Wed, 9 Oct 2024 at 20:07, Shayon Mukherjee <shayonj@gmail.com> wrote:

[thinking…] Unless - we try to do support both a GUC and the ALTER INDEX ENABLE/DISABLE grammar + isdisabled attribute on pg_index?

I just wanted to explain my point of view on this. This is my opinion
and is by no means authoritative.

I was interested in this patch when you proposed it as an ALTER INDEX
option. I know other committers seem interested, but I personally
don't have any interest in the GUC option. I think the reason I
dislike it is that it's yet another not even half-baked take on
planner hints (the other one being enable* GUCs). I often thought that
if we ever did planner hints that it would be great to have multiple
ways to specify the hints. Ordinarily, I'd expect some special comment
type as the primary method to specify hints, but equally, it would be
nice to be able to specify them in other ways. e.g. a GUC to have them
apply to more than just 1 query. Useful for things such as "don't use
index X".

Thank you so much this context, as someone new to psql-hackers, having this insight is super useful. Also getting a sense of how folks feel about controlling different behaviors like planner hints through GUC and SQL grammar.

For instance: I wasn’t quite able to figure out the how to properly distinguish + reason between the enable* GUCs and ALTER index for this case, and patches are per my limited understand of the historical context as well.

Now, I'm not suggesting you go off and code up planner hints. That's a
huge project. I'm just concerned that we've already got a fair bit of
cruft that will be left remaining if we ever get core planner hints
and a disabled_indexes GUC will just add to that. I don't feel like
the ALTER INDEX method would be leftover cruft from us gaining core
planner hints. Others might feel differently on that one. I feel the
ALTER INDEX option is less controversial.

I'll also stand by what I said earlier on this thread. If PeterG gets
index skip scans done for PG18, then it's likely there's going to be
lots of users considering if they still need a certain index or not
after upgrading to PG18.

Likewise, I personally feel that the ability to disable indexes quickly and reverse the disabling (also quickly) is super useful, especially from an operational POV (point of view). So, I am very keen on getting this landed and happy to iterate on as many patches as it takes. :D

At this point, I am indifferent to each of the approaches (GUC or SQL grammar) based on the pros/cons I shared earlier in the thread & discussions in the thread. However, I would like us to make progress on getting _something_ out since the topic of disabling indexes has come up many times on pgsql-hackers in the past years and there is no easy way to toggle this behavior yet.

“yet another not even half-baked take on planner hints" is a good way to put things about enable* GUCs, so I am very much on board with proposing an updated PATCH to support disabling of indexes through ALTER. The original PATCH was here for context [1]/messages/by-id/CANqtF-oBaBtRfw9O7GAoHN3nNEZQYsW3oaGfD+wJfG8R29nZYw@mail.gmail.com.

I am also curious about supporting this ([1]/messages/by-id/CANqtF-oBaBtRfw9O7GAoHN3nNEZQYsW3oaGfD+wJfG8R29nZYw@mail.gmail.com) through the ALTER grammar and not having the planner consider indexes by updating `get_relation_info` in `plancat.c`. Basically, through `pg_index.isdisabled`, which is already open in `get_relation_info`, we can read from `pg_index.isdisabled` and accordingly update `IndexOptInfo.isdisabled`. So, I'm happy to explore that as well and share my findings.

[1]: /messages/by-id/CANqtF-oBaBtRfw9O7GAoHN3nNEZQYsW3oaGfD+wJfG8R29nZYw@mail.gmail.com

Thanks
Shayon

#33Shayon Mukherjee
shayonj@gmail.com
In reply to: Robert Haas (#30)
Re: Proposal to Enable/Disable Index using ALTER INDEX

On Oct 9, 2024, at 1:41 PM, Robert Haas <robertmhaas@gmail.com> wrote:

On Wed, Oct 9, 2024 at 4:19 AM David Rowley <dgrowleyml@gmail.com <mailto:dgrowleyml@gmail.com>> wrote:

On Wed, 9 Oct 2024 at 20:07, Shayon Mukherjee <shayonj@gmail.com> wrote:

[thinking…] Unless - we try to do support both a GUC and the ALTER INDEX ENABLE/DISABLE grammar + isdisabled attribute on pg_index?

I just wanted to explain my point of view on this. This is my opinion
and is by no means authoritative.

I was interested in this patch when you proposed it as an ALTER INDEX
option. I know other committers seem interested, but I personally
don't have any interest in the GUC option. I think the reason I
dislike it is that it's yet another not even half-baked take on
planner hints (the other one being enable* GUCs). I often thought that
if we ever did planner hints that it would be great to have multiple
ways to specify the hints. Ordinarily, I'd expect some special comment
type as the primary method to specify hints, but equally, it would be
nice to be able to specify them in other ways. e.g. a GUC to have them
apply to more than just 1 query. Useful for things such as "don't use
index X".

+1. A GUC can be done as a contrib module using existing hooks, and I
think that's already been done outside of core, perhaps multiple
times. That certainly doesn't mean we CAN'T add it as an in-core
feature, but I do think "yet another not even half-baked take on
planner hints" is a fair description. What I would personally like to
see is for us to ship one or possibly more than one contrib module
that let people do hint-like things in useful ways, and this could be
a part of that. But I think we need better infrastructure for
controlling the planner behavior first, hence the "allowing extensions
to control planner behavior" thread.

Thank you for sharing this Robert. I like the idea behind "allowing extensions to control planner behavior” overall and I think it does help towards a powerful extension ecosystem too. I wonder if there is a reality where we can achieve both the outcomes here

- Support disabling of indexes [1]/messages/by-id/ABD42A12-4DCF-4EE4-B903-4C657903CECE@gmail.com through ALTER command
- While also building on "allowing extensions to control planner behavior” for the reasons above?

[1]: /messages/by-id/ABD42A12-4DCF-4EE4-B903-4C657903CECE@gmail.com

Thanks
Shayon

#34Robert Haas
robertmhaas@gmail.com
In reply to: Shayon Mukherjee (#33)
Re: Proposal to Enable/Disable Index using ALTER INDEX

On Sat, Oct 12, 2024 at 5:56 AM Shayon Mukherjee <shayonj@gmail.com> wrote:

Thank you for sharing this Robert. I like the idea behind "allowing extensions to control planner behavior” overall and I think it does help towards a powerful extension ecosystem too. I wonder if there is a reality where we can achieve both the outcomes here

- Support disabling of indexes [1] through ALTER command
- While also building on "allowing extensions to control planner behavior” for the reasons above?

[1] /messages/by-id/ABD42A12-4DCF-4EE4-B903-4C657903CECE@gmail.com

Yes, I think we can do both things.

--
Robert Haas
EDB: http://www.enterprisedb.com

#35David Rowley
dgrowleyml@gmail.com
In reply to: Vinícius Abrahão (#31)
Re: Proposal to Enable/Disable Index using ALTER INDEX

On Sat, 12 Oct 2024 at 22:41, Vinícius Abrahão <vinnix.bsd@gmail.com> wrote:

You are going to disable the index but not the update of it? Why? Does it imply that when you are going to re-enable it you are going to recreate it?

It might be worth you reading the discussion and proposed patches. I
think either of those would answer your questions.

I don't recall anyone ever proposing that re-enabling the index would
result in it having to be rebuilt. If that was a requirement, then I'd
say there does not seem much point in the feature. You might as well
just drop the index and recreate it if you change your mind.

David

#36David Rowley
dgrowleyml@gmail.com
In reply to: Robert Haas (#34)
Re: Proposal to Enable/Disable Index using ALTER INDEX

On Wed, 16 Oct 2024 at 03:40, Robert Haas <robertmhaas@gmail.com> wrote:

On Sat, Oct 12, 2024 at 5:56 AM Shayon Mukherjee <shayonj@gmail.com> wrote:

Thank you for sharing this Robert. I like the idea behind "allowing extensions to control planner behavior” overall and I think it does help towards a powerful extension ecosystem too. I wonder if there is a reality where we can achieve both the outcomes here

- Support disabling of indexes [1] through ALTER command
- While also building on "allowing extensions to control planner behavior” for the reasons above?

[1] /messages/by-id/ABD42A12-4DCF-4EE4-B903-4C657903CECE@gmail.com

Yes, I think we can do both things.

I think so too. I imagine there'd be cases where even hints global to
all queries running on the server wouldn't result in the index being
completely disabled. For example, a physical replica might not be
privy to the hints defined on the primary and it might just be the
queries running on the physical replica that are getting the most use
out of the given index. Having the change made in pg_index would mean
physical replicas have the index disabled too. For the primary use
case I have in mind (test disabling indexes you're considering
dropping), having the disabledness replicate would be very useful.

David

#37Peter Eisentraut
peter@eisentraut.org
In reply to: Tom Lane (#23)
Re: Proposal to Enable/Disable Index using ALTER INDEX

On 24.09.24 20:21, Tom Lane wrote:

Peter Eisentraut <peter@eisentraut.org> writes:

On 23.09.24 22:51, Shayon Mukherjee wrote:

I am happy to draft a patch for this as well. I think I have a working
idea so far of where the necessary checks might go. However if you don’t
mind, can you elaborate further on how the effect would be similar to
enable_indexscan?

Planner settings like enable_indexscan used to just add a large number
(disable_cost) to the estimated plan node costs. It's a bit more
sophisticated in PG17. But in any case, I imagine "disabling an index"
could use the same mechanism. Or maybe not, maybe the setting would
just completely ignore the index.

Yeah, I'd be inclined to implement this by having create_index_paths
just not make any paths for rejected indexes. Or you could back up
another step and keep plancat.c from building IndexOptInfos for them.
The latter might have additional effects, such as preventing the plan
from relying on a uniqueness condition enforced by the index. Not
clear to me if that's desirable or not.

Yes, I think you'd want that, because one of the purposes of this
feature would be to test whether it's okay to drop an index. So you
don't want the planner to take any account of the index for its decisions.

#38Robert Haas
robertmhaas@gmail.com
In reply to: Peter Eisentraut (#37)
Re: Proposal to Enable/Disable Index using ALTER INDEX

On Wed, Oct 16, 2024 at 8:33 AM Peter Eisentraut <peter@eisentraut.org> wrote:

Yeah, I'd be inclined to implement this by having create_index_paths
just not make any paths for rejected indexes. Or you could back up
another step and keep plancat.c from building IndexOptInfos for them.
The latter might have additional effects, such as preventing the plan
from relying on a uniqueness condition enforced by the index. Not
clear to me if that's desirable or not.

Yes, I think you'd want that, because one of the purposes of this
feature would be to test whether it's okay to drop an index. So you
don't want the planner to take any account of the index for its decisions.

I think this is right. I think we want to avoid invalidating the
index, so we still need to consider it in determining where HOT
updates must be performed, but we don't want to "improve" the plan
using the index if it's disabled.

--
Robert Haas
EDB: http://www.enterprisedb.com

#39Shayon Mukherjee
shayonj@gmail.com
In reply to: David Rowley (#36)
1 attachment(s)
Re: Proposal to Enable/Disable Index using ALTER INDEX (with patch)

On Oct 15, 2024, at 7:25 PM, David Rowley <dgrowleyml@gmail.com> wrote:

On Wed, 16 Oct 2024 at 03:40, Robert Haas <robertmhaas@gmail.com> wrote:

On Sat, Oct 12, 2024 at 5:56 AM Shayon Mukherjee <shayonj@gmail.com> wrote:

Thank you for sharing this Robert. I like the idea behind "allowing extensions to control planner behavior” overall and I think it does help towards a powerful extension ecosystem too. I wonder if there is a reality where we can achieve both the outcomes here

- Support disabling of indexes [1] through ALTER command
- While also building on "allowing extensions to control planner behavior” for the reasons above?

[1] /messages/by-id/ABD42A12-4DCF-4EE4-B903-4C657903CECE@gmail.com

Yes, I think we can do both things.

I think so too. I imagine there'd be cases where even hints global to
all queries running on the server wouldn't result in the index being
completely disabled. For example, a physical replica might not be
privy to the hints defined on the primary and it might just be the
queries running on the physical replica that are getting the most use
out of the given index. Having the change made in pg_index would mean
physical replicas have the index disabled too. For the primary use
case I have in mind (test disabling indexes you're considering
dropping), having the disabledness replicate would be very useful.

+1 and I agree.

That said - Thank you everyone for the discussions and pointers. I now have a new patch that introduces the ability to enable or disable indexes using ALTER INDEX and CREATE INDEX commands, and updating get_relation_info in plancat.c to skip disabled indexes entirely by baking in the concept into IndexOptInfo structure. Below are all the relevant details.

Original motivation for the problem and proposal for a patch can be found at [1]/messages/by-id/CANqtF-oXKe0M=0QOih6H+sZRjE2BWAbkW_1+9nMEAMLxUJg5jA@mail.gmail.com.

This patch passes all the existing specs and the newly added regression tests. The patch is ready for review and test. It compiles, so the can patch can be applied for testing as well.

Implementation details:

- New Grammar:
- ALTER INDEX ... ENABLE/DISABLE
- CREATE INDEX ... DISABLE

- Default state is enabled. Indexes are only disabled when explicitly
instructed via CREATE INDEX ... DISABLE or ALTER INDEX ... DISABLE.

- Primary Key and Unique constraint indexes are always enabled as well. The
ENABLE/DISABLE grammar is not supported for these types of indexes. They can
be later disabled via ALTER INDEX ... ENABLE/DISABLE if needed.

- ALTER INDEX ... ENABLE/DISABLE performs an in-place update of the pg_index
catalog to protect against indcheckxmin [2]/messages/by-id/20180618215635.m5vrnxdxhxytvmcm@alap3.anarazel.de (older unrelated thread).

- pg_get_indexdef() support the new functionality and grammar. This change is
reflected in \d output for tables and pg_dump. We show the DISABLE syntax accordingly.

- Updated create_index.sql regression test to cover the new grammar and verify
that disabled indexes are not used in queries. The test CATALOG_VERSION_NO

- Basic single-column and multi-column indexes
- Partial indexes
- Expression indexes
- Join indexes
- GIN and GiST indexes
- Covering indexes
- Range indexes
- Unique indexes and constraints

- Adds a new enabled attribute to the IndexOptInfo structure.

- Modifies get_relation_info in plancat.c to skip disabled indexes entirely, thus reducing the number of places we need to check if an index is disabled or not. Inspired by the conversations start at [3]/messages/by-id/3465209.1727202064@sss.pgh.pa.us.
- I chose to modify the logic within get_relation_info as compared to, say, reducing the cost to make the planner not consider an index during planning, mostly to keep the number of changes being introduced to a minimum and also the logic itself being self-contained and easier to under perhaps (?).

- No changes are made to stop the index from getting rebuilt. This way we ensure no
data miss or corruption when index is re-nabled.

- TOAST indexes are supported and enabled by default as well.

- REINDEX CONCURRENTLY is supported as well and existing state of pg_index.indisenabled
is carried over accordingly.

- See the changes in create_index.sql to get an idea of the grammar and sql statements.

- See the changes in create_index.out to get an idea of the catalogue states and EXPLAIN
output to see when an index is getting used or isn't (when disabled).

- Incorporated DavidR's feedback from [4]/messages/by-id/CAApHDvpUNu=iVcdJ74sypvgeaCF+tfpyb8VRhZaF7DTd1xVr7g@mail.gmail.com around documentation and also you will see that by skip disabled indexes entirely from get_relation_info in plancat.c (as mentioned above), we address the other mentioned issues as well.

Looking forward to any and all feedback on this patch, including but not limited to code quality, tests, fundamental logic.

[1]: /messages/by-id/CANqtF-oXKe0M=0QOih6H+sZRjE2BWAbkW_1+9nMEAMLxUJg5jA@mail.gmail.com
[2]: /messages/by-id/20180618215635.m5vrnxdxhxytvmcm@alap3.anarazel.de
[3]: /messages/by-id/3465209.1727202064@sss.pgh.pa.us
[4]: /messages/by-id/CAApHDvpUNu=iVcdJ74sypvgeaCF+tfpyb8VRhZaF7DTd1xVr7g@mail.gmail.com

Thanks
Shayon

Attachments:

v1-0001-Introduce-the-ability-to-enable-disable-indexes-u.patchapplication/octet-stream; name=v1-0001-Introduce-the-ability-to-enable-disable-indexes-u.patch; x-unix-mode=0644Download
From c3038eda9dc030e62d97eef8dcb4d033798d2988 Mon Sep 17 00:00:00 2001
From: Shayon Mukherjee <shayonj@gmail.com>
Date: Wed, 16 Oct 2024 11:07:15 -0400
Subject: [PATCH v1] Introduce the ability to enable/disable indexes using
 ALTER INDEX

---
 doc/src/sgml/catalogs.sgml                 |  11 +
 doc/src/sgml/ref/alter_index.sgml          |  43 ++
 doc/src/sgml/ref/create_index.sgml         |  29 ++
 src/backend/bootstrap/bootparse.y          |   2 +
 src/backend/catalog/index.c                |  31 +-
 src/backend/catalog/toasting.c             |   2 +-
 src/backend/commands/indexcmds.c           |   4 +
 src/backend/commands/tablecmds.c           |  67 ++-
 src/backend/optimizer/util/plancat.c       |  13 +
 src/backend/parser/gram.y                  |  48 +-
 src/backend/parser/parse_utilcmd.c         |   3 +
 src/backend/utils/adt/ruleutils.c          |   4 +
 src/backend/utils/cache/relcache.c         |   1 +
 src/include/catalog/index.h                |   2 +-
 src/include/catalog/pg_index.h             |   1 +
 src/include/nodes/parsenodes.h             |   3 +
 src/include/nodes/pathnodes.h              |   2 +
 src/test/regress/expected/create_index.out | 494 +++++++++++++++++++++
 src/test/regress/sql/create_index.sql      | 181 ++++++++
 19 files changed, 931 insertions(+), 10 deletions(-)

diff --git a/doc/src/sgml/catalogs.sgml b/doc/src/sgml/catalogs.sgml
index 964c819a02..124ca3dc35 100644
--- a/doc/src/sgml/catalogs.sgml
+++ b/doc/src/sgml/catalogs.sgml
@@ -4590,6 +4590,17 @@ SCRAM-SHA-256$<replaceable>&lt;iteration count&gt;</replaceable>:<replaceable>&l
        partial index.
       </para></entry>
      </row>
+
+     <row>
+      <entry role="catalog_table_entry"><para role="column_definition">
+       <structfield>indisenabled</structfield> <type>bool</type>
+      </para>
+      <para>
+       If true, the index is currently enabled and should be used for queries.
+       If false, the index is disabled and should not be used for queries,
+       but is still maintained when the table is modified. Default is true.
+      </para></entry>
+     </row>
     </tbody>
    </tgroup>
   </table>
diff --git a/doc/src/sgml/ref/alter_index.sgml b/doc/src/sgml/ref/alter_index.sgml
index e26efec064..c5c13a3cb3 100644
--- a/doc/src/sgml/ref/alter_index.sgml
+++ b/doc/src/sgml/ref/alter_index.sgml
@@ -31,6 +31,8 @@ ALTER INDEX [ IF EXISTS ] <replaceable class="parameter">name</replaceable> ALTE
     SET STATISTICS <replaceable class="parameter">integer</replaceable>
 ALTER INDEX ALL IN TABLESPACE <replaceable class="parameter">name</replaceable> [ OWNED BY <replaceable class="parameter">role_name</replaceable> [, ... ] ]
     SET TABLESPACE <replaceable class="parameter">new_tablespace</replaceable> [ NOWAIT ]
+ALTER INDEX [ IF EXISTS ] <replaceable class="parameter">name</replaceable> ENABLE
+ALTER INDEX [ IF EXISTS ] <replaceable class="parameter">name</replaceable> DISABLE
 </synopsis>
  </refsynopsisdiv>
 
@@ -158,6 +160,33 @@ ALTER INDEX ALL IN TABLESPACE <replaceable class="parameter">name</replaceable>
     </listitem>
    </varlistentry>
 
+   <varlistentry>
+    <term><literal>ENABLE</literal></term>
+    <listitem>
+     <para>
+      Enable the specified index. The index will be used by the query planner
+      for query optimization. This is the default state for newly created indexes.
+     </para>
+    </listitem>
+   </varlistentry>
+
+   <varlistentry>
+    <term><literal>DISABLE</literal></term>
+    <listitem>
+     <para>
+      Disable the specified index. A disabled index is not used by the query planner
+      for query optimization, but it is still maintained when the underlying table
+      data changes. This can be useful for testing query performance with and without
+      specific indexes, temporarily reducing the overhead of index maintenance
+      during bulk data loading operations, or verifying an index is not being used
+      before dropping it. If performance degrades after disabling an index, it can be
+      easily re-enabled. Before disabling, it's recommended to check
+      <structname>pg_stat_user_indexes</structname>.<structfield>idx_scan</structfield>
+      to identify potentially unused indexes.
+     </para>
+    </listitem>
+   </varlistentry>
+
   </variablelist>
   </para>
 
@@ -300,6 +329,20 @@ CREATE INDEX coord_idx ON measured (x, y, (z + t));
 ALTER INDEX coord_idx ALTER COLUMN 3 SET STATISTICS 1000;
 </programlisting></para>
 
+  <para>
+   To enable an index:
+<programlisting>
+ALTER INDEX idx_name ENABLE;
+</programlisting>
+  </para>
+
+  <para>
+   To disable an index:
+<programlisting>
+ALTER INDEX idx_name DISABLE;
+</programlisting>
+  </para>
+
  </refsect1>
 
  <refsect1>
diff --git a/doc/src/sgml/ref/create_index.sgml b/doc/src/sgml/ref/create_index.sgml
index 621bc0e253..f1eebfa250 100644
--- a/doc/src/sgml/ref/create_index.sgml
+++ b/doc/src/sgml/ref/create_index.sgml
@@ -28,6 +28,7 @@ CREATE [ UNIQUE ] INDEX [ CONCURRENTLY ] [ [ IF NOT EXISTS ] <replaceable class=
     [ WITH ( <replaceable class="parameter">storage_parameter</replaceable> [= <replaceable class="parameter">value</replaceable>] [, ... ] ) ]
     [ TABLESPACE <replaceable class="parameter">tablespace_name</replaceable> ]
     [ WHERE <replaceable class="parameter">predicate</replaceable> ]
+    [ DISABLE ]
 </synopsis>
  </refsynopsisdiv>
 
@@ -380,6 +381,19 @@ CREATE [ UNIQUE ] INDEX [ CONCURRENTLY ] [ [ IF NOT EXISTS ] <replaceable class=
       </listitem>
      </varlistentry>
 
+    <varlistentry>
+      <term><literal>DISABLE</literal></term>
+      <listitem>
+       <para>
+        Creates the index in a disabled state (default enabled). A disabled index is not used by the
+        query planner for query optimization, but it is still maintained when the
+        underlying table data changes. This can be useful when you want to create
+        an index without immediately impacting query performance, allowing you to
+        enable it later at a more convenient time. The index can be enabled later
+        using <command>ALTER INDEX ... ENABLE</command>.
+       </para>
+      </listitem>
+     </varlistentry>
     </variablelist>
 
   <refsect2 id="sql-createindex-storage-parameters" xreflabel="Index Storage Parameters">
@@ -701,6 +715,14 @@ Indexes:
     partitioned index is a metadata only operation.
    </para>
 
+  <para>
+   When creating an index with the <literal>DISABLE</literal> option, the index
+   will be created but not used for query planning. This can be useful for
+   preparing an index in advance of its use, or for testing purposes. The index
+   will still be maintained as the table is modified, so it can be enabled
+   later without needing to be rebuilt. By default all new indexes are enabled.
+  </para>
+
   </refsect2>
  </refsect1>
 
@@ -980,6 +1002,13 @@ SELECT * FROM points
 CREATE INDEX CONCURRENTLY sales_quantity_index ON sales_table (quantity);
 </programlisting></para>
 
+  <para>
+   To create an index on the table <literal>test_table</literal> with the default
+   name, but have it initially disabled:
+<programlisting>
+CREATE INDEX ON test_table (col1) DISABLE;
+</programlisting>
+  </para>
  </refsect1>
 
  <refsect1>
diff --git a/src/backend/bootstrap/bootparse.y b/src/backend/bootstrap/bootparse.y
index 73a7592fb7..6023d58490 100644
--- a/src/backend/bootstrap/bootparse.y
+++ b/src/backend/bootstrap/bootparse.y
@@ -302,6 +302,7 @@ Boot_DeclareIndexStmt:
 					stmt->concurrent = false;
 					stmt->if_not_exists = false;
 					stmt->reset_default_tblspc = false;
+					stmt->isenabled = true;
 
 					/* locks and races need not concern us in bootstrap mode */
 					relationId = RangeVarGetRelid(stmt->relation, NoLock,
@@ -355,6 +356,7 @@ Boot_DeclareUniqueIndexStmt:
 					stmt->concurrent = false;
 					stmt->if_not_exists = false;
 					stmt->reset_default_tblspc = false;
+					stmt->isenabled = true;
 
 					/* locks and races need not concern us in bootstrap mode */
 					relationId = RangeVarGetRelid(stmt->relation, NoLock,
diff --git a/src/backend/catalog/index.c b/src/backend/catalog/index.c
index 12822d0b14..15773ebb13 100644
--- a/src/backend/catalog/index.c
+++ b/src/backend/catalog/index.c
@@ -118,7 +118,8 @@ static void UpdateIndexRelation(Oid indexoid, Oid heapoid,
 								bool isexclusion,
 								bool immediate,
 								bool isvalid,
-								bool isready);
+								bool isready,
+								bool isenabled);
 static void index_update_stats(Relation rel,
 							   bool hasindex,
 							   double reltuples);
@@ -569,7 +570,8 @@ UpdateIndexRelation(Oid indexoid,
 					bool isexclusion,
 					bool immediate,
 					bool isvalid,
-					bool isready)
+					bool isready,
+					bool isenabled)
 {
 	int2vector *indkey;
 	oidvector  *indcollation;
@@ -647,6 +649,7 @@ UpdateIndexRelation(Oid indexoid,
 	values[Anum_pg_index_indisready - 1] = BoolGetDatum(isready);
 	values[Anum_pg_index_indislive - 1] = BoolGetDatum(true);
 	values[Anum_pg_index_indisreplident - 1] = BoolGetDatum(false);
+	values[Anum_pg_index_indisenabled - 1] = BoolGetDatum(isenabled);
 	values[Anum_pg_index_indkey - 1] = PointerGetDatum(indkey);
 	values[Anum_pg_index_indcollation - 1] = PointerGetDatum(indcollation);
 	values[Anum_pg_index_indclass - 1] = PointerGetDatum(indclass);
@@ -712,6 +715,8 @@ UpdateIndexRelation(Oid indexoid,
  *			already exists.
  *		INDEX_CREATE_PARTITIONED:
  *			create a partitioned index (table must be partitioned)
+ *		INDEX_CREATE_DISABLED:
+*				create the index as disabled if instructed, defaults to being enabled.
  * constr_flags: flags passed to index_constraint_create
  *		(only if INDEX_CREATE_ADD_CONSTRAINT is set)
  * allow_system_table_mods: allow table to be a system catalog
@@ -757,6 +762,7 @@ index_create(Relation heapRelation,
 	bool		invalid = (flags & INDEX_CREATE_INVALID) != 0;
 	bool		concurrent = (flags & INDEX_CREATE_CONCURRENT) != 0;
 	bool		partitioned = (flags & INDEX_CREATE_PARTITIONED) != 0;
+	bool 		isenabled  = (flags & INDEX_CREATE_ENABLED) != 0;
 	char		relkind;
 	TransactionId relfrozenxid;
 	MultiXactId relminmxid;
@@ -1040,13 +1046,15 @@ index_create(Relation heapRelation,
 	 *	  (Or, could define a rule to maintain the predicate) --Nels, Feb '92
 	 * ----------------
 	 */
+
 	UpdateIndexRelation(indexRelationId, heapRelationId, parentIndexRelid,
 						indexInfo,
 						collationIds, opclassIds, coloptions,
 						isprimary, is_exclusion,
 						(constr_flags & INDEX_CONSTR_CREATE_DEFERRABLE) == 0,
 						!concurrent && !invalid,
-						!concurrent);
+						!concurrent,
+						isenabled);
 
 	/*
 	 * Register relcache invalidation on the indexes' heap relation, to
@@ -1315,6 +1323,8 @@ index_concurrently_create_copy(Relation heapRelation, Oid oldIndexId,
 	List	   *indexColNames = NIL;
 	List	   *indexExprs = NIL;
 	List	   *indexPreds = NIL;
+	Form_pg_index indexForm;
+	bits16 	 createFlags;
 
 	indexRelation = index_open(oldIndexId, RowExclusiveLock);
 
@@ -1342,6 +1352,9 @@ index_concurrently_create_copy(Relation heapRelation, Oid oldIndexId,
 											Anum_pg_index_indoption);
 	indcoloptions = (int2vector *) DatumGetPointer(colOptionDatum);
 
+	/* Get the enabled state of the original index */
+	indexForm = (Form_pg_index) GETSTRUCT(indexTuple);
+
 	/* Fetch reloptions of index if any */
 	classTuple = SearchSysCache1(RELOID, ObjectIdGetDatum(oldIndexId));
 	if (!HeapTupleIsValid(classTuple))
@@ -1433,6 +1446,16 @@ index_concurrently_create_copy(Relation heapRelation, Oid oldIndexId,
 		stattargets[i].isnull = isnull;
 	}
 
+	/*
+	* Determine the create flags for the new index.
+	* We always use SKIP_BUILD and CONCURRENT for concurrent reindexing.
+	* If the original index was enabled, we also set the ENABLED flag
+	* to maintain the same state in the new index.
+	*/
+	createFlags = INDEX_CREATE_SKIP_BUILD | INDEX_CREATE_CONCURRENT;
+	if (indexForm->indisenabled)
+			createFlags |= INDEX_CREATE_ENABLED;
+
 	/*
 	 * Now create the new index.
 	 *
@@ -1456,7 +1479,7 @@ index_concurrently_create_copy(Relation heapRelation, Oid oldIndexId,
 							  indcoloptions->values,
 							  stattargets,
 							  reloptionsDatum,
-							  INDEX_CREATE_SKIP_BUILD | INDEX_CREATE_CONCURRENT,
+							  createFlags,
 							  0,
 							  true, /* allow table to be a system catalog? */
 							  false,	/* is_internal? */
diff --git a/src/backend/catalog/toasting.c b/src/backend/catalog/toasting.c
index ad3082c62a..dead993a74 100644
--- a/src/backend/catalog/toasting.c
+++ b/src/backend/catalog/toasting.c
@@ -325,7 +325,7 @@ create_toast_table(Relation rel, Oid toastOid, Oid toastIndexOid,
 				 BTREE_AM_OID,
 				 rel->rd_rel->reltablespace,
 				 collationIds, opclassIds, NULL, coloptions, NULL, (Datum) 0,
-				 INDEX_CREATE_IS_PRIMARY, 0, true, true, NULL);
+				 INDEX_CREATE_IS_PRIMARY | INDEX_CREATE_ENABLED, 0, true, true, NULL);
 
 	table_close(toast_rel, NoLock);
 
diff --git a/src/backend/commands/indexcmds.c b/src/backend/commands/indexcmds.c
index e33ad81529..d0604e9a00 100644
--- a/src/backend/commands/indexcmds.c
+++ b/src/backend/commands/indexcmds.c
@@ -1192,6 +1192,10 @@ DefineIndex(Oid tableId,
 		flags |= INDEX_CREATE_PARTITIONED;
 	if (stmt->primary)
 		flags |= INDEX_CREATE_IS_PRIMARY;
+   if (stmt->isenabled)
+		flags |= INDEX_CREATE_ENABLED;
+   else
+		flags &= ~INDEX_CREATE_ENABLED;
 
 	/*
 	 * If the table is partitioned, and recursion was declined but partitions
diff --git a/src/backend/commands/tablecmds.c b/src/backend/commands/tablecmds.c
index 1ccc80087c..30f623a52d 100644
--- a/src/backend/commands/tablecmds.c
+++ b/src/backend/commands/tablecmds.c
@@ -664,7 +664,7 @@ static List *GetParentedForeignKeyRefs(Relation partition);
 static void ATDetachCheckNoForeignKeyRefs(Relation partition);
 static char GetAttributeCompression(Oid atttypid, const char *compression);
 static char GetAttributeStorage(Oid atttypid, const char *storagemode);
-
+static void ATExecEnableDisableIndex(Relation rel, bool enable);
 
 /* ----------------------------------------------------------------
  *		DefineRelation
@@ -4558,6 +4558,8 @@ AlterTableGetLockLevel(List *cmds)
 			case AT_SetExpression:
 			case AT_DropExpression:
 			case AT_SetCompression:
+			case AT_EnableIndex:
+			case AT_DisableIndex:
 				cmd_lockmode = AccessExclusiveLock;
 				break;
 
@@ -5131,6 +5133,12 @@ ATPrepCmd(List **wqueue, Relation rel, AlterTableCmd *cmd,
 			/* No command-specific prep needed */
 			pass = AT_PASS_MISC;
 			break;
+		case AT_EnableIndex:
+		case AT_DisableIndex:
+			ATSimplePermissions(cmd->subtype, rel, ATT_INDEX | ATT_PARTITIONED_INDEX);
+			/* No command-specific prep needed */
+			pass = AT_PASS_MISC;
+			break;
 		default:				/* oops */
 			elog(ERROR, "unrecognized alter table type: %d",
 				 (int) cmd->subtype);
@@ -5527,6 +5535,12 @@ ATExecCmd(List **wqueue, AlteredTableInfo *tab,
 		case AT_DetachPartitionFinalize:
 			address = ATExecDetachPartitionFinalize(rel, ((PartitionCmd *) cmd->def)->name);
 			break;
+		case AT_EnableIndex:
+				ATExecEnableDisableIndex(rel, true);
+				break;
+		case AT_DisableIndex:
+				ATExecEnableDisableIndex(rel, false);
+				break;
 		default:				/* oops */
 			elog(ERROR, "unrecognized alter table type: %d",
 				 (int) cmd->subtype);
@@ -6426,6 +6440,8 @@ alter_table_type_to_string(AlterTableType cmdtype)
 			return "DROP COLUMN";
 		case AT_AddIndex:
 		case AT_ReAddIndex:
+		case AT_EnableIndex:
+		case AT_DisableIndex:
 			return NULL;		/* not real grammar */
 		case AT_AddConstraint:
 		case AT_ReAddConstraint:
@@ -20203,3 +20219,52 @@ GetAttributeStorage(Oid atttypid, const char *storagemode)
 
 	return cstorage;
 }
+
+/*
+ * ATExecEnableDisableIndex
+ * Performs an in-place update to enable or disable an index in pg_index.
+ */
+static void
+ATExecEnableDisableIndex(Relation rel, bool enable)
+{
+	Oid			indexOid = RelationGetRelid(rel);
+	Relation	pg_index;
+	HeapTuple	indexTuple;
+	Form_pg_index indexForm;
+	ScanKeyData key;
+	void	   *inplace_state = NULL;
+
+	pg_index = table_open(IndexRelationId, RowExclusiveLock);
+
+	ScanKeyInit(&key,
+				Anum_pg_index_indexrelid,
+				BTEqualStrategyNumber, F_OIDEQ,
+				ObjectIdGetDatum(indexOid));
+
+	systable_inplace_update_begin(pg_index, IndexRelidIndexId, true, NULL,
+								  1, &key, &indexTuple, &inplace_state);
+
+	if (!HeapTupleIsValid(indexTuple))
+		elog(ERROR, "could not find tuple for index %u", indexOid);
+
+	indexForm = (Form_pg_index) GETSTRUCT(indexTuple);
+
+	if (indexForm->indisenabled != enable)
+	{
+		HeapTuple newtup = heap_copytuple(indexTuple);
+		indexForm = (Form_pg_index) GETSTRUCT(newtup);
+
+		indexForm->indisenabled = enable;
+
+		systable_inplace_update_finish(inplace_state, newtup);
+		heap_freetuple(newtup);
+		CacheInvalidateRelcache(rel);
+		InvokeObjectPostAlterHook(IndexRelationId, indexOid, 0);
+	}
+	else
+	{
+		systable_inplace_update_cancel(inplace_state);
+	}
+
+	table_close(pg_index, RowExclusiveLock);
+}
diff --git a/src/backend/optimizer/util/plancat.c b/src/backend/optimizer/util/plancat.c
index b913f91ff0..d6c8bab9ab 100644
--- a/src/backend/optimizer/util/plancat.c
+++ b/src/backend/optimizer/util/plancat.c
@@ -295,6 +295,19 @@ get_relation_info(PlannerInfo *root, Oid relationObjectId, bool inhparent,
 			info->opcintype = (Oid *) palloc(sizeof(Oid) * nkeycolumns);
 			info->canreturn = (bool *) palloc(sizeof(bool) * ncolumns);
 
+			/*
+ 			 * Skip disabled indexes all together, as they should not be considered
+ 			 * for query planning. This builds the data structure for the planner's
+ 			 * use and we make it part of IndexOptInfo since the index is already open.
+ 			 * We also close the relation before continuing to the next index.
+ 			 */
+ 			info->enabled = index->indisenabled;
+ 			if (!info->enabled)
+ 			{
+ 				index_close(indexRelation, NoLock);
+ 				continue;
+ 			}
+
 			for (i = 0; i < ncolumns; i++)
 			{
 				info->indexkeys[i] = index->indkey.values[i];
diff --git a/src/backend/parser/gram.y b/src/backend/parser/gram.y
index 4aa8646af7..c5d0d66445 100644
--- a/src/backend/parser/gram.y
+++ b/src/backend/parser/gram.y
@@ -333,7 +333,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 %type <ival>	add_drop opt_asc_desc opt_nulls_order
 
 %type <node>	alter_table_cmd alter_type_cmd opt_collate_clause
-	   replica_identity partition_cmd index_partition_cmd
+	   replica_identity partition_cmd index_partition_cmd index_alter_cmd
 %type <list>	alter_table_cmds alter_type_cmds
 %type <list>    alter_identity_column_option_list
 %type <defelt>  alter_identity_column_option
@@ -496,6 +496,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 %type <boolean> opt_unique opt_verbose opt_full
 %type <boolean> opt_freeze opt_analyze opt_default
 %type <defelt>	opt_binary copy_delimiter
+%type <boolean>  opt_index_enabled
 
 %type <boolean> copy_from opt_program
 
@@ -2168,6 +2169,24 @@ AlterTableStmt:
 					n->nowait = $13;
 					$$ = (Node *) n;
 				}
+		| ALTER INDEX qualified_name index_alter_cmd
+				{
+					AlterTableStmt *n = makeNode(AlterTableStmt);
+					n->relation = $3;
+					n->cmds = list_make1($4);
+					n->objtype = OBJECT_INDEX;
+					n->missing_ok = false;
+					$$ = (Node *) n;
+				}
+		| ALTER INDEX IF_P EXISTS qualified_name index_alter_cmd
+				{
+					AlterTableStmt *n = makeNode(AlterTableStmt);
+					n->relation = $5;
+					n->cmds = list_make1($6);
+					n->objtype = OBJECT_INDEX;
+					n->missing_ok = true;
+					$$ = (Node *) n;
+				}
 		|	ALTER INDEX qualified_name alter_table_cmds
 				{
 					AlterTableStmt *n = makeNode(AlterTableStmt);
@@ -2393,6 +2412,21 @@ index_partition_cmd:
 				}
 		;
 
+index_alter_cmd:
+		/* ALTER INDEX <name> ENABLE|DISABLE */
+		ENABLE_P
+			{
+				AlterTableCmd *n = makeNode(AlterTableCmd);
+				n->subtype = AT_EnableIndex;
+				$$ = (Node *) n;
+			}
+		| DISABLE_P
+			{
+				AlterTableCmd *n = makeNode(AlterTableCmd);
+				n->subtype = AT_DisableIndex;
+				$$ = (Node *) n;
+			}
+		;
 alter_table_cmd:
 			/* ALTER TABLE <name> ADD <coldef> */
 			ADD_P columnDef
@@ -8126,7 +8160,7 @@ defacl_privilege_target:
 
 IndexStmt:	CREATE opt_unique INDEX opt_concurrently opt_single_name
 			ON relation_expr access_method_clause '(' index_params ')'
-			opt_include opt_unique_null_treatment opt_reloptions OptTableSpace where_clause
+			opt_include opt_unique_null_treatment opt_reloptions OptTableSpace where_clause opt_index_enabled
 				{
 					IndexStmt *n = makeNode(IndexStmt);
 
@@ -8141,6 +8175,7 @@ IndexStmt:	CREATE opt_unique INDEX opt_concurrently opt_single_name
 					n->options = $14;
 					n->tableSpace = $15;
 					n->whereClause = $16;
+					n->isenabled = $17;
 					n->excludeOpNames = NIL;
 					n->idxcomment = NULL;
 					n->indexOid = InvalidOid;
@@ -8158,7 +8193,7 @@ IndexStmt:	CREATE opt_unique INDEX opt_concurrently opt_single_name
 				}
 			| CREATE opt_unique INDEX opt_concurrently IF_P NOT EXISTS name
 			ON relation_expr access_method_clause '(' index_params ')'
-			opt_include opt_unique_null_treatment opt_reloptions OptTableSpace where_clause
+			opt_include opt_unique_null_treatment opt_reloptions OptTableSpace where_clause opt_index_enabled
 				{
 					IndexStmt *n = makeNode(IndexStmt);
 
@@ -8173,6 +8208,7 @@ IndexStmt:	CREATE opt_unique INDEX opt_concurrently opt_single_name
 					n->options = $17;
 					n->tableSpace = $18;
 					n->whereClause = $19;
+					n->isenabled = $20;
 					n->excludeOpNames = NIL;
 					n->idxcomment = NULL;
 					n->indexOid = InvalidOid;
@@ -8195,6 +8231,12 @@ opt_unique:
 			| /*EMPTY*/								{ $$ = false; }
 		;
 
+opt_index_enabled:
+			ENABLE_P                      { $$ = true; }
+			| DISABLE_P                   { $$ = false; }
+			| /*EMPTY*/                 	{ $$ = true; }
+		;
+
 access_method_clause:
 			USING name								{ $$ = $2; }
 			| /*EMPTY*/								{ $$ = DEFAULT_INDEX_TYPE; }
diff --git a/src/backend/parser/parse_utilcmd.c b/src/backend/parser/parse_utilcmd.c
index 1e15ce10b4..32554612ed 100644
--- a/src/backend/parser/parse_utilcmd.c
+++ b/src/backend/parser/parse_utilcmd.c
@@ -1588,6 +1588,7 @@ generateClonedIndexStmt(RangeVar *heapRel, Relation source_idx,
 	index->concurrent = false;
 	index->if_not_exists = false;
 	index->reset_default_tblspc = false;
+	index->isenabled = idxrec->indisenabled;
 
 	/*
 	 * We don't try to preserve the name of the source index; instead, just
@@ -2214,6 +2215,8 @@ transformIndexConstraint(Constraint *constraint, CreateStmtContext *cxt)
 	index->concurrent = false;
 	index->if_not_exists = false;
 	index->reset_default_tblspc = constraint->reset_default_tblspc;
+	/* Ensure indexes for constraints are created as enabled by default */
+	index->isenabled = true;
 
 	/*
 	 * If it's ALTER TABLE ADD CONSTRAINT USING INDEX, look up the index and
diff --git a/src/backend/utils/adt/ruleutils.c b/src/backend/utils/adt/ruleutils.c
index 2177d17e27..05b27ca232 100644
--- a/src/backend/utils/adt/ruleutils.c
+++ b/src/backend/utils/adt/ruleutils.c
@@ -1559,6 +1559,10 @@ pg_get_indexdef_worker(Oid indexrelid, int colno,
 			else
 				appendStringInfo(&buf, " WHERE %s", str);
 		}
+
+		/* Add DISABLE clause if the index is disabled */
+		if (!idxrec->indisenabled)
+				appendStringInfoString(&buf, " DISABLE");
 	}
 
 	/* Clean up */
diff --git a/src/backend/utils/cache/relcache.c b/src/backend/utils/cache/relcache.c
index c326f687eb..b3b43df080 100644
--- a/src/backend/utils/cache/relcache.c
+++ b/src/backend/utils/cache/relcache.c
@@ -2344,6 +2344,7 @@ RelationReloadIndexInfo(Relation relation)
 		relation->rd_index->indisready = index->indisready;
 		relation->rd_index->indislive = index->indislive;
 		relation->rd_index->indisreplident = index->indisreplident;
+		relation->rd_index->indisenabled = index->indisenabled;
 
 		/* Copy xmin too, as that is needed to make sense of indcheckxmin */
 		HeapTupleHeaderSetXmin(relation->rd_indextuple->t_data,
diff --git a/src/include/catalog/index.h b/src/include/catalog/index.h
index 2dea96f47c..8a47cfd174 100644
--- a/src/include/catalog/index.h
+++ b/src/include/catalog/index.h
@@ -65,6 +65,7 @@ extern void index_check_primary_key(Relation heapRel,
 #define	INDEX_CREATE_IF_NOT_EXISTS			(1 << 4)
 #define	INDEX_CREATE_PARTITIONED			(1 << 5)
 #define INDEX_CREATE_INVALID				(1 << 6)
+#define INDEX_CREATE_ENABLED        (1 << 7)
 
 extern Oid	index_create(Relation heapRelation,
 						 const char *indexRelationName,
@@ -175,7 +176,6 @@ extern void RestoreReindexState(const void *reindexstate);
 
 extern void IndexSetParentIndex(Relation partitionIdx, Oid parentOid);
 
-
 /*
  * itemptr_encode - Encode ItemPointer as int64/int8
  *
diff --git a/src/include/catalog/pg_index.h b/src/include/catalog/pg_index.h
index 6c89639a9e..b0c7e5f365 100644
--- a/src/include/catalog/pg_index.h
+++ b/src/include/catalog/pg_index.h
@@ -44,6 +44,7 @@ CATALOG(pg_index,2610,IndexRelationId) BKI_SCHEMA_MACRO
 	bool		indisready;		/* is this index ready for inserts? */
 	bool		indislive;		/* is this index alive at all? */
 	bool		indisreplident; /* is this index the identity for replication? */
+	bool		indisenabled;	/* is this index enabled for use by queries? */
 
 	/* variable-length fields start here, but we allow direct access to indkey */
 	int2vector	indkey BKI_FORCE_NOT_NULL;	/* column numbers of indexed cols,
diff --git a/src/include/nodes/parsenodes.h b/src/include/nodes/parsenodes.h
index c92cef3d16..0252b0e30a 100644
--- a/src/include/nodes/parsenodes.h
+++ b/src/include/nodes/parsenodes.h
@@ -2414,6 +2414,8 @@ typedef enum AlterTableType
 	AT_SetIdentity,				/* SET identity column options */
 	AT_DropIdentity,			/* DROP IDENTITY */
 	AT_ReAddStatistics,			/* internal to commands/tablecmds.c */
+	AT_EnableIndex,				/* ENABLE INDEX */
+  AT_DisableIndex,			/* DISABLE INDEX */
 } AlterTableType;
 
 typedef struct ReplicaIdentityStmt
@@ -3392,6 +3394,7 @@ typedef struct IndexStmt
 	bool		if_not_exists;	/* just do nothing if index already exists? */
 	bool		reset_default_tblspc;	/* reset default_tablespace prior to
 										 * executing */
+  bool    isenabled;		/* true if ENABLE (default), false if DISABLE */
 } IndexStmt;
 
 /* ----------------------
diff --git a/src/include/nodes/pathnodes.h b/src/include/nodes/pathnodes.h
index 07e2415398..ae224ab400 100644
--- a/src/include/nodes/pathnodes.h
+++ b/src/include/nodes/pathnodes.h
@@ -1207,6 +1207,8 @@ struct IndexOptInfo
 	/* AM's cost estimator */
 	/* Rather than include amapi.h here, we declare amcostestimate like this */
 	void		(*amcostestimate) () pg_node_attr(read_write_ignore);
+	/* true if this index is enabled */
+ 	bool		enabled;
 };
 
 /*
diff --git a/src/test/regress/expected/create_index.out b/src/test/regress/expected/create_index.out
index d3358dfc39..22513ae978 100644
--- a/src/test/regress/expected/create_index.out
+++ b/src/test/regress/expected/create_index.out
@@ -2965,6 +2965,500 @@ ERROR:  REINDEX SCHEMA cannot run inside a transaction block
 END;
 -- concurrently
 REINDEX SCHEMA CONCURRENTLY schema_to_reindex;
+-- Test enable/disable functionality for indexes
+-- Setup
+CREATE TABLE index_test(
+    id INT PRIMARY KEY,
+    data TEXT,
+    num INT,
+    vector INT[],
+    range INT4RANGE
+);
+INSERT INTO index_test
+SELECT
+    g,
+    'data ' || g,
+    g % 100,
+    ARRAY[g, g+1, g+2],
+    int4range(g, g+10)
+FROM generate_series(1, 1000) g;
+-- Function for testing
+CREATE FUNCTION get_data_length(text) RETURNS INT AS $$
+    SELECT length($1);
+$$ LANGUAGE SQL IMMUTABLE;
+-- Helper function to show index status
+CREATE OR REPLACE FUNCTION show_index_status(index_name text)
+RETURNS TABLE (
+    indexrelid regclass,
+    indisvalid boolean,
+    indisready boolean,
+    indislive boolean,
+    indisenabled boolean
+) AS $$
+BEGIN
+    RETURN QUERY EXECUTE format('
+        SELECT indexrelid::regclass, indisvalid, indisready, indislive, indisenabled
+        FROM pg_index
+        WHERE indexrelid = %L::regclass', index_name);
+END;
+$$ LANGUAGE plpgsql;
+-- Create and test each index type
+-- 1. Basic single-column index
+CREATE INDEX idx_single ON index_test(data);
+SELECT show_index_status('idx_single');
+  show_index_status   
+----------------------
+ (idx_single,t,t,t,t)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE data = 'data 500';
+                  QUERY PLAN                   
+-----------------------------------------------
+ Bitmap Heap Scan on index_test
+   Recheck Cond: (data = 'data 500'::text)
+   ->  Bitmap Index Scan on idx_single
+         Index Cond: (data = 'data 500'::text)
+(4 rows)
+
+ALTER INDEX idx_single DISABLE;
+SELECT show_index_status('idx_single');
+  show_index_status   
+----------------------
+ (idx_single,t,t,t,f)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE data = 'data 500';
+             QUERY PLAN              
+-------------------------------------
+ Seq Scan on index_test
+   Filter: (data = 'data 500'::text)
+(2 rows)
+
+ALTER INDEX idx_single ENABLE;
+SELECT show_index_status('idx_single');
+  show_index_status   
+----------------------
+ (idx_single,t,t,t,t)
+(1 row)
+
+-- 2. Multi-column index
+CREATE INDEX idx_multi ON index_test(num, data);
+SELECT show_index_status('idx_multi');
+  show_index_status  
+---------------------
+ (idx_multi,t,t,t,t)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE num = 50 AND data > 'data 500';
+                           QUERY PLAN                           
+----------------------------------------------------------------
+ Bitmap Heap Scan on index_test
+   Recheck Cond: ((num = 50) AND (data > 'data 500'::text))
+   ->  Bitmap Index Scan on idx_multi
+         Index Cond: ((num = 50) AND (data > 'data 500'::text))
+(4 rows)
+
+ALTER INDEX idx_multi DISABLE;
+SELECT show_index_status('idx_multi');
+  show_index_status  
+---------------------
+ (idx_multi,t,t,t,f)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE num = 50 AND data > 'data 500';
+                      QUERY PLAN                      
+------------------------------------------------------
+ Seq Scan on index_test
+   Filter: ((data > 'data 500'::text) AND (num = 50))
+(2 rows)
+
+ALTER INDEX idx_multi ENABLE;
+SELECT show_index_status('idx_multi');
+  show_index_status  
+---------------------
+ (idx_multi,t,t,t,t)
+(1 row)
+
+-- 3. Partial index
+CREATE INDEX idx_partial ON index_test(num) WHERE num < 50;
+SELECT show_index_status('idx_partial');
+   show_index_status   
+-----------------------
+ (idx_partial,t,t,t,t)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE num = 25;
+               QUERY PLAN               
+----------------------------------------
+ Bitmap Heap Scan on index_test
+   Recheck Cond: (num = 25)
+   ->  Bitmap Index Scan on idx_partial
+         Index Cond: (num = 25)
+(4 rows)
+
+ALTER INDEX idx_partial DISABLE;
+SELECT show_index_status('idx_partial');
+   show_index_status   
+-----------------------
+ (idx_partial,t,t,t,f)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE num = 25;
+              QUERY PLAN              
+--------------------------------------
+ Bitmap Heap Scan on index_test
+   Recheck Cond: (num = 25)
+   ->  Bitmap Index Scan on idx_multi
+         Index Cond: (num = 25)
+(4 rows)
+
+ALTER INDEX idx_partial ENABLE;
+SELECT show_index_status('idx_partial');
+   show_index_status   
+-----------------------
+ (idx_partial,t,t,t,t)
+(1 row)
+
+-- 4. Expression index
+CREATE INDEX idx_expression ON index_test((lower(data)));
+SELECT show_index_status('idx_expression');
+    show_index_status     
+--------------------------
+ (idx_expression,t,t,t,t)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE lower(data) = 'data 500';
+                      QUERY PLAN                      
+------------------------------------------------------
+ Bitmap Heap Scan on index_test
+   Recheck Cond: (lower(data) = 'data 500'::text)
+   ->  Bitmap Index Scan on idx_expression
+         Index Cond: (lower(data) = 'data 500'::text)
+(4 rows)
+
+ALTER INDEX idx_expression DISABLE;
+SELECT show_index_status('idx_expression');
+    show_index_status     
+--------------------------
+ (idx_expression,t,t,t,f)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE lower(data) = 'data 500';
+                 QUERY PLAN                 
+--------------------------------------------
+ Seq Scan on index_test
+   Filter: (lower(data) = 'data 500'::text)
+(2 rows)
+
+ALTER INDEX idx_expression ENABLE;
+SELECT show_index_status('idx_expression');
+    show_index_status     
+--------------------------
+ (idx_expression,t,t,t,t)
+(1 row)
+
+-- 5. GIN index
+CREATE INDEX idx_gin ON index_test USING gin(vector);
+SELECT show_index_status('idx_gin');
+ show_index_status 
+-------------------
+ (idx_gin,t,t,t,t)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE vector @> ARRAY[500];
+                     QUERY PLAN                     
+----------------------------------------------------
+ Bitmap Heap Scan on index_test
+   Recheck Cond: (vector @> '{500}'::integer[])
+   ->  Bitmap Index Scan on idx_gin
+         Index Cond: (vector @> '{500}'::integer[])
+(4 rows)
+
+ALTER INDEX idx_gin DISABLE;
+SELECT show_index_status('idx_gin');
+ show_index_status 
+-------------------
+ (idx_gin,t,t,t,f)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE vector @> ARRAY[500];
+                QUERY PLAN                
+------------------------------------------
+ Seq Scan on index_test
+   Filter: (vector @> '{500}'::integer[])
+(2 rows)
+
+ALTER INDEX idx_gin ENABLE;
+SELECT show_index_status('idx_gin');
+ show_index_status 
+-------------------
+ (idx_gin,t,t,t,t)
+(1 row)
+
+-- 6. GiST index
+CREATE INDEX idx_gist ON index_test USING gist(range);
+SELECT show_index_status('idx_gist');
+ show_index_status  
+--------------------
+ (idx_gist,t,t,t,t)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE range && int4range(100, 110);
+                      QUERY PLAN                       
+-------------------------------------------------------
+ Bitmap Heap Scan on index_test
+   Recheck Cond: (range && '[100,110)'::int4range)
+   ->  Bitmap Index Scan on idx_gist
+         Index Cond: (range && '[100,110)'::int4range)
+(4 rows)
+
+ALTER INDEX idx_gist DISABLE;
+SELECT show_index_status('idx_gist');
+ show_index_status  
+--------------------
+ (idx_gist,t,t,t,f)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE range && int4range(100, 110);
+                 QUERY PLAN                  
+---------------------------------------------
+ Seq Scan on index_test
+   Filter: (range && '[100,110)'::int4range)
+(2 rows)
+
+ALTER INDEX idx_gist ENABLE;
+SELECT show_index_status('idx_gist');
+ show_index_status  
+--------------------
+ (idx_gist,t,t,t,t)
+(1 row)
+
+-- 7. Covering index
+CREATE INDEX idx_covering ON index_test(num) INCLUDE (data);
+SELECT show_index_status('idx_covering');
+   show_index_status    
+------------------------
+ (idx_covering,t,t,t,t)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT num, data FROM index_test WHERE num = 50;
+               QUERY PLAN                
+-----------------------------------------
+ Bitmap Heap Scan on index_test
+   Recheck Cond: (num = 50)
+   ->  Bitmap Index Scan on idx_covering
+         Index Cond: (num = 50)
+(4 rows)
+
+ALTER INDEX idx_covering DISABLE;
+SELECT show_index_status('idx_covering');
+   show_index_status    
+------------------------
+ (idx_covering,t,t,t,f)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT num, data FROM index_test WHERE num = 50;
+              QUERY PLAN              
+--------------------------------------
+ Bitmap Heap Scan on index_test
+   Recheck Cond: (num = 50)
+   ->  Bitmap Index Scan on idx_multi
+         Index Cond: (num = 50)
+(4 rows)
+
+ALTER INDEX idx_covering ENABLE;
+SELECT show_index_status('idx_covering');
+   show_index_status    
+------------------------
+ (idx_covering,t,t,t,t)
+(1 row)
+
+-- 8. Unique index
+CREATE UNIQUE INDEX idx_unique ON index_test(id, data);
+SELECT show_index_status('idx_unique');
+  show_index_status   
+----------------------
+ (idx_unique,t,t,t,t)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE id = 500 AND data = 'data 500';
+                        QUERY PLAN                        
+----------------------------------------------------------
+ Index Scan using idx_unique on index_test
+   Index Cond: ((id = 500) AND (data = 'data 500'::text))
+(2 rows)
+
+ALTER INDEX idx_unique DISABLE;
+SELECT show_index_status('idx_unique');
+  show_index_status   
+----------------------
+ (idx_unique,t,t,t,f)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE id = 500 AND data = 'data 500';
+                   QUERY PLAN                   
+------------------------------------------------
+ Index Scan using index_test_pkey on index_test
+   Index Cond: (id = 500)
+   Filter: (data = 'data 500'::text)
+(3 rows)
+
+ALTER INDEX idx_unique ENABLE;
+SELECT show_index_status('idx_unique');
+  show_index_status   
+----------------------
+ (idx_unique,t,t,t,t)
+(1 row)
+
+-- 9. Function-based index
+CREATE INDEX idx_func ON index_test(get_data_length(data));
+SELECT show_index_status('idx_func');
+ show_index_status  
+--------------------
+ (idx_func,t,t,t,t)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE get_data_length(data) = 10;
+               QUERY PLAN                
+-----------------------------------------
+ Bitmap Heap Scan on index_test
+   Recheck Cond: (length(data) = 10)
+   ->  Bitmap Index Scan on idx_func
+         Index Cond: (length(data) = 10)
+(4 rows)
+
+ALTER INDEX idx_func DISABLE;
+SELECT show_index_status('idx_func');
+ show_index_status  
+--------------------
+ (idx_func,t,t,t,f)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE get_data_length(data) = 10;
+          QUERY PLAN           
+-------------------------------
+ Seq Scan on index_test
+   Filter: (length(data) = 10)
+(2 rows)
+
+ALTER INDEX idx_func ENABLE;
+SELECT show_index_status('idx_func');
+ show_index_status  
+--------------------
+ (idx_func,t,t,t,t)
+(1 row)
+
+-- 10. Join index
+CREATE TABLE join_test (id INT PRIMARY KEY, ref_id INT);
+INSERT INTO join_test SELECT g, g % 100 FROM generate_series(1, 1000) g;
+CREATE INDEX idx_join ON join_test(ref_id);
+SELECT show_index_status('idx_join');
+ show_index_status  
+--------------------
+ (idx_join,t,t,t,t)
+(1 row)
+
+EXPLAIN (COSTS OFF)
+SELECT jt.id, it.data
+FROM join_test jt
+JOIN index_test it ON jt.ref_id = it.num
+WHERE jt.id BETWEEN 100 AND 200;
+                          QUERY PLAN                           
+---------------------------------------------------------------
+ Hash Join
+   Hash Cond: (it.num = jt.ref_id)
+   ->  Seq Scan on index_test it
+   ->  Hash
+         ->  Bitmap Heap Scan on join_test jt
+               Recheck Cond: ((id >= 100) AND (id <= 200))
+               ->  Bitmap Index Scan on join_test_pkey
+                     Index Cond: ((id >= 100) AND (id <= 200))
+(8 rows)
+
+-- Disable all indexes to force seq scan
+ALTER INDEX idx_join DISABLE;
+ALTER INDEX join_test_pkey DISABLE;
+SELECT show_index_status('idx_join');
+ show_index_status  
+--------------------
+ (idx_join,t,t,t,f)
+(1 row)
+
+SELECT show_index_status('join_test_pkey');
+    show_index_status     
+--------------------------
+ (join_test_pkey,t,t,t,f)
+(1 row)
+
+EXPLAIN (COSTS OFF)
+SELECT jt.id, it.data
+FROM join_test jt
+JOIN index_test it ON jt.ref_id = it.num
+WHERE jt.id BETWEEN 100 AND 200;
+                     QUERY PLAN                      
+-----------------------------------------------------
+ Hash Join
+   Hash Cond: (it.num = jt.ref_id)
+   ->  Seq Scan on index_test it
+   ->  Hash
+         ->  Seq Scan on join_test jt
+               Filter: ((id >= 100) AND (id <= 200))
+(6 rows)
+
+ALTER INDEX idx_join ENABLE;
+ALTER INDEX join_test_pkey ENABLE;
+SELECT show_index_status('idx_join');
+ show_index_status  
+--------------------
+ (idx_join,t,t,t,t)
+(1 row)
+
+SELECT show_index_status('join_test_pkey');
+    show_index_status     
+--------------------------
+ (join_test_pkey,t,t,t,t)
+(1 row)
+
+-- Test REINDEX CONCURRENTLY
+REINDEX INDEX CONCURRENTLY idx_join;
+SELECT show_index_status('idx_join');
+ show_index_status  
+--------------------
+ (idx_join,t,t,t,t)
+(1 row)
+
+ALTER INDEX idx_join DISABLE;
+SELECT show_index_status('idx_join');
+ show_index_status  
+--------------------
+ (idx_join,t,t,t,f)
+(1 row)
+
+REINDEX INDEX CONCURRENTLY idx_join;
+SELECT show_index_status('idx_join');
+ show_index_status  
+--------------------
+ (idx_join,t,t,t,f)
+(1 row)
+
+SELECT pg_get_indexdef('idx_join'::regclass);
+                                  pg_get_indexdef                                  
+-----------------------------------------------------------------------------------
+ CREATE INDEX idx_join ON schema_to_reindex.join_test USING btree (ref_id) DISABLE
+(1 row)
+
+ALTER INDEX idx_join ENABLE;
+SELECT pg_get_indexdef('idx_join'::regclass);
+                              pg_get_indexdef                              
+---------------------------------------------------------------------------
+ CREATE INDEX idx_join ON schema_to_reindex.join_test USING btree (ref_id)
+(1 row)
+
+-- Clean up
+DROP TABLE index_test;
+DROP TABLE join_test;
+DROP FUNCTION get_data_length;
+DROP FUNCTION show_index_status;
 -- Failure for unauthorized user
 CREATE ROLE regress_reindexuser NOLOGIN;
 SET SESSION ROLE regress_reindexuser;
diff --git a/src/test/regress/sql/create_index.sql b/src/test/regress/sql/create_index.sql
index fe162cc7c3..db547898aa 100644
--- a/src/test/regress/sql/create_index.sql
+++ b/src/test/regress/sql/create_index.sql
@@ -1297,6 +1297,187 @@ END;
 -- concurrently
 REINDEX SCHEMA CONCURRENTLY schema_to_reindex;
 
+-- Test enable/disable functionality for indexes
+
+-- Setup
+CREATE TABLE index_test(
+    id INT PRIMARY KEY,
+    data TEXT,
+    num INT,
+    vector INT[],
+    range INT4RANGE
+);
+
+INSERT INTO index_test
+SELECT
+    g,
+    'data ' || g,
+    g % 100,
+    ARRAY[g, g+1, g+2],
+    int4range(g, g+10)
+FROM generate_series(1, 1000) g;
+
+-- Function for testing
+CREATE FUNCTION get_data_length(text) RETURNS INT AS $$
+    SELECT length($1);
+$$ LANGUAGE SQL IMMUTABLE;
+
+-- Helper function to show index status
+CREATE OR REPLACE FUNCTION show_index_status(index_name text)
+RETURNS TABLE (
+    indexrelid regclass,
+    indisvalid boolean,
+    indisready boolean,
+    indislive boolean,
+    indisenabled boolean
+) AS $$
+BEGIN
+    RETURN QUERY EXECUTE format('
+        SELECT indexrelid::regclass, indisvalid, indisready, indislive, indisenabled
+        FROM pg_index
+        WHERE indexrelid = %L::regclass', index_name);
+END;
+$$ LANGUAGE plpgsql;
+
+-- Create and test each index type
+-- 1. Basic single-column index
+CREATE INDEX idx_single ON index_test(data);
+SELECT show_index_status('idx_single');
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE data = 'data 500';
+ALTER INDEX idx_single DISABLE;
+SELECT show_index_status('idx_single');
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE data = 'data 500';
+ALTER INDEX idx_single ENABLE;
+SELECT show_index_status('idx_single');
+
+-- 2. Multi-column index
+CREATE INDEX idx_multi ON index_test(num, data);
+SELECT show_index_status('idx_multi');
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE num = 50 AND data > 'data 500';
+ALTER INDEX idx_multi DISABLE;
+SELECT show_index_status('idx_multi');
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE num = 50 AND data > 'data 500';
+ALTER INDEX idx_multi ENABLE;
+SELECT show_index_status('idx_multi');
+
+-- 3. Partial index
+CREATE INDEX idx_partial ON index_test(num) WHERE num < 50;
+SELECT show_index_status('idx_partial');
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE num = 25;
+ALTER INDEX idx_partial DISABLE;
+SELECT show_index_status('idx_partial');
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE num = 25;
+ALTER INDEX idx_partial ENABLE;
+SELECT show_index_status('idx_partial');
+
+-- 4. Expression index
+CREATE INDEX idx_expression ON index_test((lower(data)));
+SELECT show_index_status('idx_expression');
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE lower(data) = 'data 500';
+ALTER INDEX idx_expression DISABLE;
+SELECT show_index_status('idx_expression');
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE lower(data) = 'data 500';
+ALTER INDEX idx_expression ENABLE;
+SELECT show_index_status('idx_expression');
+
+-- 5. GIN index
+CREATE INDEX idx_gin ON index_test USING gin(vector);
+SELECT show_index_status('idx_gin');
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE vector @> ARRAY[500];
+ALTER INDEX idx_gin DISABLE;
+SELECT show_index_status('idx_gin');
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE vector @> ARRAY[500];
+ALTER INDEX idx_gin ENABLE;
+SELECT show_index_status('idx_gin');
+
+-- 6. GiST index
+CREATE INDEX idx_gist ON index_test USING gist(range);
+SELECT show_index_status('idx_gist');
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE range && int4range(100, 110);
+ALTER INDEX idx_gist DISABLE;
+SELECT show_index_status('idx_gist');
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE range && int4range(100, 110);
+ALTER INDEX idx_gist ENABLE;
+SELECT show_index_status('idx_gist');
+
+-- 7. Covering index
+CREATE INDEX idx_covering ON index_test(num) INCLUDE (data);
+SELECT show_index_status('idx_covering');
+EXPLAIN (COSTS OFF) SELECT num, data FROM index_test WHERE num = 50;
+ALTER INDEX idx_covering DISABLE;
+SELECT show_index_status('idx_covering');
+EXPLAIN (COSTS OFF) SELECT num, data FROM index_test WHERE num = 50;
+ALTER INDEX idx_covering ENABLE;
+SELECT show_index_status('idx_covering');
+
+-- 8. Unique index
+CREATE UNIQUE INDEX idx_unique ON index_test(id, data);
+SELECT show_index_status('idx_unique');
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE id = 500 AND data = 'data 500';
+ALTER INDEX idx_unique DISABLE;
+SELECT show_index_status('idx_unique');
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE id = 500 AND data = 'data 500';
+ALTER INDEX idx_unique ENABLE;
+SELECT show_index_status('idx_unique');
+
+-- 9. Function-based index
+CREATE INDEX idx_func ON index_test(get_data_length(data));
+SELECT show_index_status('idx_func');
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE get_data_length(data) = 10;
+ALTER INDEX idx_func DISABLE;
+SELECT show_index_status('idx_func');
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE get_data_length(data) = 10;
+ALTER INDEX idx_func ENABLE;
+SELECT show_index_status('idx_func');
+
+-- 10. Join index
+CREATE TABLE join_test (id INT PRIMARY KEY, ref_id INT);
+INSERT INTO join_test SELECT g, g % 100 FROM generate_series(1, 1000) g;
+CREATE INDEX idx_join ON join_test(ref_id);
+SELECT show_index_status('idx_join');
+
+EXPLAIN (COSTS OFF)
+SELECT jt.id, it.data
+FROM join_test jt
+JOIN index_test it ON jt.ref_id = it.num
+WHERE jt.id BETWEEN 100 AND 200;
+
+-- Disable all indexes to force seq scan
+ALTER INDEX idx_join DISABLE;
+ALTER INDEX join_test_pkey DISABLE;
+SELECT show_index_status('idx_join');
+SELECT show_index_status('join_test_pkey');
+
+EXPLAIN (COSTS OFF)
+SELECT jt.id, it.data
+FROM join_test jt
+JOIN index_test it ON jt.ref_id = it.num
+WHERE jt.id BETWEEN 100 AND 200;
+
+ALTER INDEX idx_join ENABLE;
+ALTER INDEX join_test_pkey ENABLE;
+SELECT show_index_status('idx_join');
+SELECT show_index_status('join_test_pkey');
+
+-- Test REINDEX CONCURRENTLY
+REINDEX INDEX CONCURRENTLY idx_join;
+SELECT show_index_status('idx_join');
+
+ALTER INDEX idx_join DISABLE;
+SELECT show_index_status('idx_join');
+REINDEX INDEX CONCURRENTLY idx_join;
+SELECT show_index_status('idx_join');
+
+SELECT pg_get_indexdef('idx_join'::regclass);
+ALTER INDEX idx_join ENABLE;
+SELECT pg_get_indexdef('idx_join'::regclass);
+
+-- Clean up
+DROP TABLE index_test;
+DROP TABLE join_test;
+DROP FUNCTION get_data_length;
+DROP FUNCTION show_index_status;
+
 -- Failure for unauthorized user
 CREATE ROLE regress_reindexuser NOLOGIN;
 SET SESSION ROLE regress_reindexuser;
-- 
2.37.1 (Apple Git-137.1)

#40Shayon Mukherjee
shayonj@gmail.com
In reply to: Shayon Mukherjee (#39)
1 attachment(s)
Re: Proposal to Enable/Disable Index using ALTER INDEX (with patch)

On Oct 16, 2024, at 12:19 PM, Shayon Mukherjee <shayonj@gmail.com> wrote:

- ALTER INDEX ... ENABLE/DISABLE performs an in-place update of the pg_index
catalog to protect against indcheckxmin [2] (older unrelated thread).

Performing the in place update of the pg_index row from ATExecEnableDisableIndex using systable_inplace_update_begin was failing in CI weirdly but not on my local MacBook when running spec suite. I am also wondering what is causing the requirement [1]/messages/by-id/20180618215635.m5vrnxdxhxytvmcm@alap3.anarazel.de to update the row in-place vs say using CatalogTupleUpdate since using the later is working well locally + CI?

I have attached a v2 patch (following from the last v1 patch [1]/messages/by-id/20180618215635.m5vrnxdxhxytvmcm@alap3.anarazel.de) that uses CatalogTupleUpdate and local + CI [2]/messages/by-id/EF2313B8-A017-4869-9B7F-A24EDD8795DE@gmail.com is passing.

[1]: /messages/by-id/20180618215635.m5vrnxdxhxytvmcm@alap3.anarazel.de
[2]: /messages/by-id/EF2313B8-A017-4869-9B7F-A24EDD8795DE@gmail.com
[3]: https://github.com/shayonj/postgres/pull/1

Thanks
Shayon

Attachments:

v2-0001-Introduce-the-ability-to-enable-disable-indexes-u.patchapplication/octet-stream; name=v2-0001-Introduce-the-ability-to-enable-disable-indexes-u.patch; x-unix-mode=0644Download
From b7d8e240b6f7cbe873fad1595d2bc79ebe38464b Mon Sep 17 00:00:00 2001
From: Shayon Mukherjee <shayonj@gmail.com>
Date: Wed, 16 Oct 2024 14:06:59 -0400
Subject: [PATCH v2] Introduce the ability to enable/disable indexes using
 ALTER INDEX

---
 doc/src/sgml/catalogs.sgml                 |  11 +
 doc/src/sgml/ref/alter_index.sgml          |  43 ++
 doc/src/sgml/ref/create_index.sgml         |  29 ++
 src/backend/bootstrap/bootparse.y          |   2 +
 src/backend/catalog/index.c                |  31 +-
 src/backend/catalog/toasting.c             |   2 +-
 src/backend/commands/indexcmds.c           |   4 +
 src/backend/commands/tablecmds.c           |  58 ++-
 src/backend/optimizer/util/plancat.c       |  13 +
 src/backend/parser/gram.y                  |  48 +-
 src/backend/parser/parse_utilcmd.c         |   3 +
 src/backend/utils/adt/ruleutils.c          |   4 +
 src/backend/utils/cache/relcache.c         |   1 +
 src/include/catalog/index.h                |   2 +-
 src/include/catalog/pg_index.h             |   1 +
 src/include/nodes/parsenodes.h             |   3 +
 src/include/nodes/pathnodes.h              |   2 +
 src/test/regress/expected/create_index.out | 494 +++++++++++++++++++++
 src/test/regress/sql/create_index.sql      | 181 ++++++++
 19 files changed, 922 insertions(+), 10 deletions(-)

diff --git a/doc/src/sgml/catalogs.sgml b/doc/src/sgml/catalogs.sgml
index 964c819a02..124ca3dc35 100644
--- a/doc/src/sgml/catalogs.sgml
+++ b/doc/src/sgml/catalogs.sgml
@@ -4590,6 +4590,17 @@ SCRAM-SHA-256$<replaceable>&lt;iteration count&gt;</replaceable>:<replaceable>&l
        partial index.
       </para></entry>
      </row>
+
+     <row>
+      <entry role="catalog_table_entry"><para role="column_definition">
+       <structfield>indisenabled</structfield> <type>bool</type>
+      </para>
+      <para>
+       If true, the index is currently enabled and should be used for queries.
+       If false, the index is disabled and should not be used for queries,
+       but is still maintained when the table is modified. Default is true.
+      </para></entry>
+     </row>
     </tbody>
    </tgroup>
   </table>
diff --git a/doc/src/sgml/ref/alter_index.sgml b/doc/src/sgml/ref/alter_index.sgml
index e26efec064..c5c13a3cb3 100644
--- a/doc/src/sgml/ref/alter_index.sgml
+++ b/doc/src/sgml/ref/alter_index.sgml
@@ -31,6 +31,8 @@ ALTER INDEX [ IF EXISTS ] <replaceable class="parameter">name</replaceable> ALTE
     SET STATISTICS <replaceable class="parameter">integer</replaceable>
 ALTER INDEX ALL IN TABLESPACE <replaceable class="parameter">name</replaceable> [ OWNED BY <replaceable class="parameter">role_name</replaceable> [, ... ] ]
     SET TABLESPACE <replaceable class="parameter">new_tablespace</replaceable> [ NOWAIT ]
+ALTER INDEX [ IF EXISTS ] <replaceable class="parameter">name</replaceable> ENABLE
+ALTER INDEX [ IF EXISTS ] <replaceable class="parameter">name</replaceable> DISABLE
 </synopsis>
  </refsynopsisdiv>
 
@@ -158,6 +160,33 @@ ALTER INDEX ALL IN TABLESPACE <replaceable class="parameter">name</replaceable>
     </listitem>
    </varlistentry>
 
+   <varlistentry>
+    <term><literal>ENABLE</literal></term>
+    <listitem>
+     <para>
+      Enable the specified index. The index will be used by the query planner
+      for query optimization. This is the default state for newly created indexes.
+     </para>
+    </listitem>
+   </varlistentry>
+
+   <varlistentry>
+    <term><literal>DISABLE</literal></term>
+    <listitem>
+     <para>
+      Disable the specified index. A disabled index is not used by the query planner
+      for query optimization, but it is still maintained when the underlying table
+      data changes. This can be useful for testing query performance with and without
+      specific indexes, temporarily reducing the overhead of index maintenance
+      during bulk data loading operations, or verifying an index is not being used
+      before dropping it. If performance degrades after disabling an index, it can be
+      easily re-enabled. Before disabling, it's recommended to check
+      <structname>pg_stat_user_indexes</structname>.<structfield>idx_scan</structfield>
+      to identify potentially unused indexes.
+     </para>
+    </listitem>
+   </varlistentry>
+
   </variablelist>
   </para>
 
@@ -300,6 +329,20 @@ CREATE INDEX coord_idx ON measured (x, y, (z + t));
 ALTER INDEX coord_idx ALTER COLUMN 3 SET STATISTICS 1000;
 </programlisting></para>
 
+  <para>
+   To enable an index:
+<programlisting>
+ALTER INDEX idx_name ENABLE;
+</programlisting>
+  </para>
+
+  <para>
+   To disable an index:
+<programlisting>
+ALTER INDEX idx_name DISABLE;
+</programlisting>
+  </para>
+
  </refsect1>
 
  <refsect1>
diff --git a/doc/src/sgml/ref/create_index.sgml b/doc/src/sgml/ref/create_index.sgml
index 621bc0e253..f1eebfa250 100644
--- a/doc/src/sgml/ref/create_index.sgml
+++ b/doc/src/sgml/ref/create_index.sgml
@@ -28,6 +28,7 @@ CREATE [ UNIQUE ] INDEX [ CONCURRENTLY ] [ [ IF NOT EXISTS ] <replaceable class=
     [ WITH ( <replaceable class="parameter">storage_parameter</replaceable> [= <replaceable class="parameter">value</replaceable>] [, ... ] ) ]
     [ TABLESPACE <replaceable class="parameter">tablespace_name</replaceable> ]
     [ WHERE <replaceable class="parameter">predicate</replaceable> ]
+    [ DISABLE ]
 </synopsis>
  </refsynopsisdiv>
 
@@ -380,6 +381,19 @@ CREATE [ UNIQUE ] INDEX [ CONCURRENTLY ] [ [ IF NOT EXISTS ] <replaceable class=
       </listitem>
      </varlistentry>
 
+    <varlistentry>
+      <term><literal>DISABLE</literal></term>
+      <listitem>
+       <para>
+        Creates the index in a disabled state (default enabled). A disabled index is not used by the
+        query planner for query optimization, but it is still maintained when the
+        underlying table data changes. This can be useful when you want to create
+        an index without immediately impacting query performance, allowing you to
+        enable it later at a more convenient time. The index can be enabled later
+        using <command>ALTER INDEX ... ENABLE</command>.
+       </para>
+      </listitem>
+     </varlistentry>
     </variablelist>
 
   <refsect2 id="sql-createindex-storage-parameters" xreflabel="Index Storage Parameters">
@@ -701,6 +715,14 @@ Indexes:
     partitioned index is a metadata only operation.
    </para>
 
+  <para>
+   When creating an index with the <literal>DISABLE</literal> option, the index
+   will be created but not used for query planning. This can be useful for
+   preparing an index in advance of its use, or for testing purposes. The index
+   will still be maintained as the table is modified, so it can be enabled
+   later without needing to be rebuilt. By default all new indexes are enabled.
+  </para>
+
   </refsect2>
  </refsect1>
 
@@ -980,6 +1002,13 @@ SELECT * FROM points
 CREATE INDEX CONCURRENTLY sales_quantity_index ON sales_table (quantity);
 </programlisting></para>
 
+  <para>
+   To create an index on the table <literal>test_table</literal> with the default
+   name, but have it initially disabled:
+<programlisting>
+CREATE INDEX ON test_table (col1) DISABLE;
+</programlisting>
+  </para>
  </refsect1>
 
  <refsect1>
diff --git a/src/backend/bootstrap/bootparse.y b/src/backend/bootstrap/bootparse.y
index 73a7592fb7..6023d58490 100644
--- a/src/backend/bootstrap/bootparse.y
+++ b/src/backend/bootstrap/bootparse.y
@@ -302,6 +302,7 @@ Boot_DeclareIndexStmt:
 					stmt->concurrent = false;
 					stmt->if_not_exists = false;
 					stmt->reset_default_tblspc = false;
+					stmt->isenabled = true;
 
 					/* locks and races need not concern us in bootstrap mode */
 					relationId = RangeVarGetRelid(stmt->relation, NoLock,
@@ -355,6 +356,7 @@ Boot_DeclareUniqueIndexStmt:
 					stmt->concurrent = false;
 					stmt->if_not_exists = false;
 					stmt->reset_default_tblspc = false;
+					stmt->isenabled = true;
 
 					/* locks and races need not concern us in bootstrap mode */
 					relationId = RangeVarGetRelid(stmt->relation, NoLock,
diff --git a/src/backend/catalog/index.c b/src/backend/catalog/index.c
index 12822d0b14..15773ebb13 100644
--- a/src/backend/catalog/index.c
+++ b/src/backend/catalog/index.c
@@ -118,7 +118,8 @@ static void UpdateIndexRelation(Oid indexoid, Oid heapoid,
 								bool isexclusion,
 								bool immediate,
 								bool isvalid,
-								bool isready);
+								bool isready,
+								bool isenabled);
 static void index_update_stats(Relation rel,
 							   bool hasindex,
 							   double reltuples);
@@ -569,7 +570,8 @@ UpdateIndexRelation(Oid indexoid,
 					bool isexclusion,
 					bool immediate,
 					bool isvalid,
-					bool isready)
+					bool isready,
+					bool isenabled)
 {
 	int2vector *indkey;
 	oidvector  *indcollation;
@@ -647,6 +649,7 @@ UpdateIndexRelation(Oid indexoid,
 	values[Anum_pg_index_indisready - 1] = BoolGetDatum(isready);
 	values[Anum_pg_index_indislive - 1] = BoolGetDatum(true);
 	values[Anum_pg_index_indisreplident - 1] = BoolGetDatum(false);
+	values[Anum_pg_index_indisenabled - 1] = BoolGetDatum(isenabled);
 	values[Anum_pg_index_indkey - 1] = PointerGetDatum(indkey);
 	values[Anum_pg_index_indcollation - 1] = PointerGetDatum(indcollation);
 	values[Anum_pg_index_indclass - 1] = PointerGetDatum(indclass);
@@ -712,6 +715,8 @@ UpdateIndexRelation(Oid indexoid,
  *			already exists.
  *		INDEX_CREATE_PARTITIONED:
  *			create a partitioned index (table must be partitioned)
+ *		INDEX_CREATE_DISABLED:
+*				create the index as disabled if instructed, defaults to being enabled.
  * constr_flags: flags passed to index_constraint_create
  *		(only if INDEX_CREATE_ADD_CONSTRAINT is set)
  * allow_system_table_mods: allow table to be a system catalog
@@ -757,6 +762,7 @@ index_create(Relation heapRelation,
 	bool		invalid = (flags & INDEX_CREATE_INVALID) != 0;
 	bool		concurrent = (flags & INDEX_CREATE_CONCURRENT) != 0;
 	bool		partitioned = (flags & INDEX_CREATE_PARTITIONED) != 0;
+	bool 		isenabled  = (flags & INDEX_CREATE_ENABLED) != 0;
 	char		relkind;
 	TransactionId relfrozenxid;
 	MultiXactId relminmxid;
@@ -1040,13 +1046,15 @@ index_create(Relation heapRelation,
 	 *	  (Or, could define a rule to maintain the predicate) --Nels, Feb '92
 	 * ----------------
 	 */
+
 	UpdateIndexRelation(indexRelationId, heapRelationId, parentIndexRelid,
 						indexInfo,
 						collationIds, opclassIds, coloptions,
 						isprimary, is_exclusion,
 						(constr_flags & INDEX_CONSTR_CREATE_DEFERRABLE) == 0,
 						!concurrent && !invalid,
-						!concurrent);
+						!concurrent,
+						isenabled);
 
 	/*
 	 * Register relcache invalidation on the indexes' heap relation, to
@@ -1315,6 +1323,8 @@ index_concurrently_create_copy(Relation heapRelation, Oid oldIndexId,
 	List	   *indexColNames = NIL;
 	List	   *indexExprs = NIL;
 	List	   *indexPreds = NIL;
+	Form_pg_index indexForm;
+	bits16 	 createFlags;
 
 	indexRelation = index_open(oldIndexId, RowExclusiveLock);
 
@@ -1342,6 +1352,9 @@ index_concurrently_create_copy(Relation heapRelation, Oid oldIndexId,
 											Anum_pg_index_indoption);
 	indcoloptions = (int2vector *) DatumGetPointer(colOptionDatum);
 
+	/* Get the enabled state of the original index */
+	indexForm = (Form_pg_index) GETSTRUCT(indexTuple);
+
 	/* Fetch reloptions of index if any */
 	classTuple = SearchSysCache1(RELOID, ObjectIdGetDatum(oldIndexId));
 	if (!HeapTupleIsValid(classTuple))
@@ -1433,6 +1446,16 @@ index_concurrently_create_copy(Relation heapRelation, Oid oldIndexId,
 		stattargets[i].isnull = isnull;
 	}
 
+	/*
+	* Determine the create flags for the new index.
+	* We always use SKIP_BUILD and CONCURRENT for concurrent reindexing.
+	* If the original index was enabled, we also set the ENABLED flag
+	* to maintain the same state in the new index.
+	*/
+	createFlags = INDEX_CREATE_SKIP_BUILD | INDEX_CREATE_CONCURRENT;
+	if (indexForm->indisenabled)
+			createFlags |= INDEX_CREATE_ENABLED;
+
 	/*
 	 * Now create the new index.
 	 *
@@ -1456,7 +1479,7 @@ index_concurrently_create_copy(Relation heapRelation, Oid oldIndexId,
 							  indcoloptions->values,
 							  stattargets,
 							  reloptionsDatum,
-							  INDEX_CREATE_SKIP_BUILD | INDEX_CREATE_CONCURRENT,
+							  createFlags,
 							  0,
 							  true, /* allow table to be a system catalog? */
 							  false,	/* is_internal? */
diff --git a/src/backend/catalog/toasting.c b/src/backend/catalog/toasting.c
index ad3082c62a..dead993a74 100644
--- a/src/backend/catalog/toasting.c
+++ b/src/backend/catalog/toasting.c
@@ -325,7 +325,7 @@ create_toast_table(Relation rel, Oid toastOid, Oid toastIndexOid,
 				 BTREE_AM_OID,
 				 rel->rd_rel->reltablespace,
 				 collationIds, opclassIds, NULL, coloptions, NULL, (Datum) 0,
-				 INDEX_CREATE_IS_PRIMARY, 0, true, true, NULL);
+				 INDEX_CREATE_IS_PRIMARY | INDEX_CREATE_ENABLED, 0, true, true, NULL);
 
 	table_close(toast_rel, NoLock);
 
diff --git a/src/backend/commands/indexcmds.c b/src/backend/commands/indexcmds.c
index e33ad81529..d0604e9a00 100644
--- a/src/backend/commands/indexcmds.c
+++ b/src/backend/commands/indexcmds.c
@@ -1192,6 +1192,10 @@ DefineIndex(Oid tableId,
 		flags |= INDEX_CREATE_PARTITIONED;
 	if (stmt->primary)
 		flags |= INDEX_CREATE_IS_PRIMARY;
+   if (stmt->isenabled)
+		flags |= INDEX_CREATE_ENABLED;
+   else
+		flags &= ~INDEX_CREATE_ENABLED;
 
 	/*
 	 * If the table is partitioned, and recursion was declined but partitions
diff --git a/src/backend/commands/tablecmds.c b/src/backend/commands/tablecmds.c
index 1ccc80087c..7ccd15b06d 100644
--- a/src/backend/commands/tablecmds.c
+++ b/src/backend/commands/tablecmds.c
@@ -664,7 +664,7 @@ static List *GetParentedForeignKeyRefs(Relation partition);
 static void ATDetachCheckNoForeignKeyRefs(Relation partition);
 static char GetAttributeCompression(Oid atttypid, const char *compression);
 static char GetAttributeStorage(Oid atttypid, const char *storagemode);
-
+static void ATExecEnableDisableIndex(Relation rel, bool enable);
 
 /* ----------------------------------------------------------------
  *		DefineRelation
@@ -4558,6 +4558,8 @@ AlterTableGetLockLevel(List *cmds)
 			case AT_SetExpression:
 			case AT_DropExpression:
 			case AT_SetCompression:
+			case AT_EnableIndex:
+			case AT_DisableIndex:
 				cmd_lockmode = AccessExclusiveLock;
 				break;
 
@@ -5131,6 +5133,12 @@ ATPrepCmd(List **wqueue, Relation rel, AlterTableCmd *cmd,
 			/* No command-specific prep needed */
 			pass = AT_PASS_MISC;
 			break;
+		case AT_EnableIndex:
+		case AT_DisableIndex:
+			ATSimplePermissions(cmd->subtype, rel, ATT_INDEX | ATT_PARTITIONED_INDEX);
+			/* No command-specific prep needed */
+			pass = AT_PASS_MISC;
+			break;
 		default:				/* oops */
 			elog(ERROR, "unrecognized alter table type: %d",
 				 (int) cmd->subtype);
@@ -5527,6 +5535,12 @@ ATExecCmd(List **wqueue, AlteredTableInfo *tab,
 		case AT_DetachPartitionFinalize:
 			address = ATExecDetachPartitionFinalize(rel, ((PartitionCmd *) cmd->def)->name);
 			break;
+		case AT_EnableIndex:
+				ATExecEnableDisableIndex(rel, true);
+				break;
+		case AT_DisableIndex:
+				ATExecEnableDisableIndex(rel, false);
+				break;
 		default:				/* oops */
 			elog(ERROR, "unrecognized alter table type: %d",
 				 (int) cmd->subtype);
@@ -6426,6 +6440,8 @@ alter_table_type_to_string(AlterTableType cmdtype)
 			return "DROP COLUMN";
 		case AT_AddIndex:
 		case AT_ReAddIndex:
+		case AT_EnableIndex:
+		case AT_DisableIndex:
 			return NULL;		/* not real grammar */
 		case AT_AddConstraint:
 		case AT_ReAddConstraint:
@@ -20203,3 +20219,43 @@ GetAttributeStorage(Oid atttypid, const char *storagemode)
 
 	return cstorage;
 }
+
+/*
+ * ATExecEnableDisableIndex
+ * Performs a catalog update to enable or disable an index in pg_index.
+ */
+static void
+ATExecEnableDisableIndex(Relation rel, bool enable)
+{
+	Oid         indexOid = RelationGetRelid(rel);
+	Relation    pg_index;
+	HeapTuple   indexTuple;
+	Form_pg_index indexForm;
+	bool        updated = false;
+
+	pg_index = table_open(IndexRelationId, RowExclusiveLock);
+
+	indexTuple = SearchSysCacheCopy1(INDEXRELID, ObjectIdGetDatum(indexOid));
+	if (!HeapTupleIsValid(indexTuple))
+		elog(ERROR, "could not find tuple for index %u", indexOid);
+
+	indexForm = (Form_pg_index) GETSTRUCT(indexTuple);
+
+	if (indexForm->indisenabled != enable)
+	{
+		indexForm->indisenabled = enable;
+
+		CatalogTupleUpdate(pg_index, &indexTuple->t_self, indexTuple);
+		updated = true;
+	}
+
+	heap_freetuple(indexTuple);
+	table_close(pg_index, RowExclusiveLock);
+
+	if (updated)
+	{
+		CacheInvalidateRelcache(rel);
+		InvokeObjectPostAlterHook(IndexRelationId, indexOid, 0);
+		CommandCounterIncrement();
+	}
+}
diff --git a/src/backend/optimizer/util/plancat.c b/src/backend/optimizer/util/plancat.c
index b913f91ff0..eaa15a1f53 100644
--- a/src/backend/optimizer/util/plancat.c
+++ b/src/backend/optimizer/util/plancat.c
@@ -295,6 +295,19 @@ get_relation_info(PlannerInfo *root, Oid relationObjectId, bool inhparent,
 			info->opcintype = (Oid *) palloc(sizeof(Oid) * nkeycolumns);
 			info->canreturn = (bool *) palloc(sizeof(bool) * ncolumns);
 
+			/*
+			 * Skip disabled indexes altogether, as they should not be considered
+			 * for query planning. This builds the data structure for the planner's
+			 * use and we make it part of IndexOptInfo since the index is already open.
+			 * We also close the relation before continuing to the next index.
+			 */
+			info->enabled = index->indisenabled;
+			if (!info->enabled)
+			{
+				index_close(indexRelation, NoLock);
+				continue;
+			}
+
 			for (i = 0; i < ncolumns; i++)
 			{
 				info->indexkeys[i] = index->indkey.values[i];
diff --git a/src/backend/parser/gram.y b/src/backend/parser/gram.y
index 4aa8646af7..c5d0d66445 100644
--- a/src/backend/parser/gram.y
+++ b/src/backend/parser/gram.y
@@ -333,7 +333,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 %type <ival>	add_drop opt_asc_desc opt_nulls_order
 
 %type <node>	alter_table_cmd alter_type_cmd opt_collate_clause
-	   replica_identity partition_cmd index_partition_cmd
+	   replica_identity partition_cmd index_partition_cmd index_alter_cmd
 %type <list>	alter_table_cmds alter_type_cmds
 %type <list>    alter_identity_column_option_list
 %type <defelt>  alter_identity_column_option
@@ -496,6 +496,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 %type <boolean> opt_unique opt_verbose opt_full
 %type <boolean> opt_freeze opt_analyze opt_default
 %type <defelt>	opt_binary copy_delimiter
+%type <boolean>  opt_index_enabled
 
 %type <boolean> copy_from opt_program
 
@@ -2168,6 +2169,24 @@ AlterTableStmt:
 					n->nowait = $13;
 					$$ = (Node *) n;
 				}
+		| ALTER INDEX qualified_name index_alter_cmd
+				{
+					AlterTableStmt *n = makeNode(AlterTableStmt);
+					n->relation = $3;
+					n->cmds = list_make1($4);
+					n->objtype = OBJECT_INDEX;
+					n->missing_ok = false;
+					$$ = (Node *) n;
+				}
+		| ALTER INDEX IF_P EXISTS qualified_name index_alter_cmd
+				{
+					AlterTableStmt *n = makeNode(AlterTableStmt);
+					n->relation = $5;
+					n->cmds = list_make1($6);
+					n->objtype = OBJECT_INDEX;
+					n->missing_ok = true;
+					$$ = (Node *) n;
+				}
 		|	ALTER INDEX qualified_name alter_table_cmds
 				{
 					AlterTableStmt *n = makeNode(AlterTableStmt);
@@ -2393,6 +2412,21 @@ index_partition_cmd:
 				}
 		;
 
+index_alter_cmd:
+		/* ALTER INDEX <name> ENABLE|DISABLE */
+		ENABLE_P
+			{
+				AlterTableCmd *n = makeNode(AlterTableCmd);
+				n->subtype = AT_EnableIndex;
+				$$ = (Node *) n;
+			}
+		| DISABLE_P
+			{
+				AlterTableCmd *n = makeNode(AlterTableCmd);
+				n->subtype = AT_DisableIndex;
+				$$ = (Node *) n;
+			}
+		;
 alter_table_cmd:
 			/* ALTER TABLE <name> ADD <coldef> */
 			ADD_P columnDef
@@ -8126,7 +8160,7 @@ defacl_privilege_target:
 
 IndexStmt:	CREATE opt_unique INDEX opt_concurrently opt_single_name
 			ON relation_expr access_method_clause '(' index_params ')'
-			opt_include opt_unique_null_treatment opt_reloptions OptTableSpace where_clause
+			opt_include opt_unique_null_treatment opt_reloptions OptTableSpace where_clause opt_index_enabled
 				{
 					IndexStmt *n = makeNode(IndexStmt);
 
@@ -8141,6 +8175,7 @@ IndexStmt:	CREATE opt_unique INDEX opt_concurrently opt_single_name
 					n->options = $14;
 					n->tableSpace = $15;
 					n->whereClause = $16;
+					n->isenabled = $17;
 					n->excludeOpNames = NIL;
 					n->idxcomment = NULL;
 					n->indexOid = InvalidOid;
@@ -8158,7 +8193,7 @@ IndexStmt:	CREATE opt_unique INDEX opt_concurrently opt_single_name
 				}
 			| CREATE opt_unique INDEX opt_concurrently IF_P NOT EXISTS name
 			ON relation_expr access_method_clause '(' index_params ')'
-			opt_include opt_unique_null_treatment opt_reloptions OptTableSpace where_clause
+			opt_include opt_unique_null_treatment opt_reloptions OptTableSpace where_clause opt_index_enabled
 				{
 					IndexStmt *n = makeNode(IndexStmt);
 
@@ -8173,6 +8208,7 @@ IndexStmt:	CREATE opt_unique INDEX opt_concurrently opt_single_name
 					n->options = $17;
 					n->tableSpace = $18;
 					n->whereClause = $19;
+					n->isenabled = $20;
 					n->excludeOpNames = NIL;
 					n->idxcomment = NULL;
 					n->indexOid = InvalidOid;
@@ -8195,6 +8231,12 @@ opt_unique:
 			| /*EMPTY*/								{ $$ = false; }
 		;
 
+opt_index_enabled:
+			ENABLE_P                      { $$ = true; }
+			| DISABLE_P                   { $$ = false; }
+			| /*EMPTY*/                 	{ $$ = true; }
+		;
+
 access_method_clause:
 			USING name								{ $$ = $2; }
 			| /*EMPTY*/								{ $$ = DEFAULT_INDEX_TYPE; }
diff --git a/src/backend/parser/parse_utilcmd.c b/src/backend/parser/parse_utilcmd.c
index 1e15ce10b4..32554612ed 100644
--- a/src/backend/parser/parse_utilcmd.c
+++ b/src/backend/parser/parse_utilcmd.c
@@ -1588,6 +1588,7 @@ generateClonedIndexStmt(RangeVar *heapRel, Relation source_idx,
 	index->concurrent = false;
 	index->if_not_exists = false;
 	index->reset_default_tblspc = false;
+	index->isenabled = idxrec->indisenabled;
 
 	/*
 	 * We don't try to preserve the name of the source index; instead, just
@@ -2214,6 +2215,8 @@ transformIndexConstraint(Constraint *constraint, CreateStmtContext *cxt)
 	index->concurrent = false;
 	index->if_not_exists = false;
 	index->reset_default_tblspc = constraint->reset_default_tblspc;
+	/* Ensure indexes for constraints are created as enabled by default */
+	index->isenabled = true;
 
 	/*
 	 * If it's ALTER TABLE ADD CONSTRAINT USING INDEX, look up the index and
diff --git a/src/backend/utils/adt/ruleutils.c b/src/backend/utils/adt/ruleutils.c
index 2177d17e27..05b27ca232 100644
--- a/src/backend/utils/adt/ruleutils.c
+++ b/src/backend/utils/adt/ruleutils.c
@@ -1559,6 +1559,10 @@ pg_get_indexdef_worker(Oid indexrelid, int colno,
 			else
 				appendStringInfo(&buf, " WHERE %s", str);
 		}
+
+		/* Add DISABLE clause if the index is disabled */
+		if (!idxrec->indisenabled)
+				appendStringInfoString(&buf, " DISABLE");
 	}
 
 	/* Clean up */
diff --git a/src/backend/utils/cache/relcache.c b/src/backend/utils/cache/relcache.c
index c326f687eb..b3b43df080 100644
--- a/src/backend/utils/cache/relcache.c
+++ b/src/backend/utils/cache/relcache.c
@@ -2344,6 +2344,7 @@ RelationReloadIndexInfo(Relation relation)
 		relation->rd_index->indisready = index->indisready;
 		relation->rd_index->indislive = index->indislive;
 		relation->rd_index->indisreplident = index->indisreplident;
+		relation->rd_index->indisenabled = index->indisenabled;
 
 		/* Copy xmin too, as that is needed to make sense of indcheckxmin */
 		HeapTupleHeaderSetXmin(relation->rd_indextuple->t_data,
diff --git a/src/include/catalog/index.h b/src/include/catalog/index.h
index 2dea96f47c..8a47cfd174 100644
--- a/src/include/catalog/index.h
+++ b/src/include/catalog/index.h
@@ -65,6 +65,7 @@ extern void index_check_primary_key(Relation heapRel,
 #define	INDEX_CREATE_IF_NOT_EXISTS			(1 << 4)
 #define	INDEX_CREATE_PARTITIONED			(1 << 5)
 #define INDEX_CREATE_INVALID				(1 << 6)
+#define INDEX_CREATE_ENABLED        (1 << 7)
 
 extern Oid	index_create(Relation heapRelation,
 						 const char *indexRelationName,
@@ -175,7 +176,6 @@ extern void RestoreReindexState(const void *reindexstate);
 
 extern void IndexSetParentIndex(Relation partitionIdx, Oid parentOid);
 
-
 /*
  * itemptr_encode - Encode ItemPointer as int64/int8
  *
diff --git a/src/include/catalog/pg_index.h b/src/include/catalog/pg_index.h
index 6c89639a9e..b0c7e5f365 100644
--- a/src/include/catalog/pg_index.h
+++ b/src/include/catalog/pg_index.h
@@ -44,6 +44,7 @@ CATALOG(pg_index,2610,IndexRelationId) BKI_SCHEMA_MACRO
 	bool		indisready;		/* is this index ready for inserts? */
 	bool		indislive;		/* is this index alive at all? */
 	bool		indisreplident; /* is this index the identity for replication? */
+	bool		indisenabled;	/* is this index enabled for use by queries? */
 
 	/* variable-length fields start here, but we allow direct access to indkey */
 	int2vector	indkey BKI_FORCE_NOT_NULL;	/* column numbers of indexed cols,
diff --git a/src/include/nodes/parsenodes.h b/src/include/nodes/parsenodes.h
index c92cef3d16..8b85e91985 100644
--- a/src/include/nodes/parsenodes.h
+++ b/src/include/nodes/parsenodes.h
@@ -2414,6 +2414,8 @@ typedef enum AlterTableType
 	AT_SetIdentity,				/* SET identity column options */
 	AT_DropIdentity,			/* DROP IDENTITY */
 	AT_ReAddStatistics,			/* internal to commands/tablecmds.c */
+	AT_EnableIndex,					/* ENABLE INDEX */
+	AT_DisableIndex,				/* DISABLE INDEX */
 } AlterTableType;
 
 typedef struct ReplicaIdentityStmt
@@ -3392,6 +3394,7 @@ typedef struct IndexStmt
 	bool		if_not_exists;	/* just do nothing if index already exists? */
 	bool		reset_default_tblspc;	/* reset default_tablespace prior to
 										 * executing */
+  bool		isenabled;		/* true if ENABLE (default), false if DISABLE */
 } IndexStmt;
 
 /* ----------------------
diff --git a/src/include/nodes/pathnodes.h b/src/include/nodes/pathnodes.h
index 07e2415398..67a4d80d92 100644
--- a/src/include/nodes/pathnodes.h
+++ b/src/include/nodes/pathnodes.h
@@ -1207,6 +1207,8 @@ struct IndexOptInfo
 	/* AM's cost estimator */
 	/* Rather than include amapi.h here, we declare amcostestimate like this */
 	void		(*amcostestimate) () pg_node_attr(read_write_ignore);
+	/* true if this index is enabled */
+	bool		enabled;
 };
 
 /*
diff --git a/src/test/regress/expected/create_index.out b/src/test/regress/expected/create_index.out
index d3358dfc39..22513ae978 100644
--- a/src/test/regress/expected/create_index.out
+++ b/src/test/regress/expected/create_index.out
@@ -2965,6 +2965,500 @@ ERROR:  REINDEX SCHEMA cannot run inside a transaction block
 END;
 -- concurrently
 REINDEX SCHEMA CONCURRENTLY schema_to_reindex;
+-- Test enable/disable functionality for indexes
+-- Setup
+CREATE TABLE index_test(
+    id INT PRIMARY KEY,
+    data TEXT,
+    num INT,
+    vector INT[],
+    range INT4RANGE
+);
+INSERT INTO index_test
+SELECT
+    g,
+    'data ' || g,
+    g % 100,
+    ARRAY[g, g+1, g+2],
+    int4range(g, g+10)
+FROM generate_series(1, 1000) g;
+-- Function for testing
+CREATE FUNCTION get_data_length(text) RETURNS INT AS $$
+    SELECT length($1);
+$$ LANGUAGE SQL IMMUTABLE;
+-- Helper function to show index status
+CREATE OR REPLACE FUNCTION show_index_status(index_name text)
+RETURNS TABLE (
+    indexrelid regclass,
+    indisvalid boolean,
+    indisready boolean,
+    indislive boolean,
+    indisenabled boolean
+) AS $$
+BEGIN
+    RETURN QUERY EXECUTE format('
+        SELECT indexrelid::regclass, indisvalid, indisready, indislive, indisenabled
+        FROM pg_index
+        WHERE indexrelid = %L::regclass', index_name);
+END;
+$$ LANGUAGE plpgsql;
+-- Create and test each index type
+-- 1. Basic single-column index
+CREATE INDEX idx_single ON index_test(data);
+SELECT show_index_status('idx_single');
+  show_index_status   
+----------------------
+ (idx_single,t,t,t,t)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE data = 'data 500';
+                  QUERY PLAN                   
+-----------------------------------------------
+ Bitmap Heap Scan on index_test
+   Recheck Cond: (data = 'data 500'::text)
+   ->  Bitmap Index Scan on idx_single
+         Index Cond: (data = 'data 500'::text)
+(4 rows)
+
+ALTER INDEX idx_single DISABLE;
+SELECT show_index_status('idx_single');
+  show_index_status   
+----------------------
+ (idx_single,t,t,t,f)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE data = 'data 500';
+             QUERY PLAN              
+-------------------------------------
+ Seq Scan on index_test
+   Filter: (data = 'data 500'::text)
+(2 rows)
+
+ALTER INDEX idx_single ENABLE;
+SELECT show_index_status('idx_single');
+  show_index_status   
+----------------------
+ (idx_single,t,t,t,t)
+(1 row)
+
+-- 2. Multi-column index
+CREATE INDEX idx_multi ON index_test(num, data);
+SELECT show_index_status('idx_multi');
+  show_index_status  
+---------------------
+ (idx_multi,t,t,t,t)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE num = 50 AND data > 'data 500';
+                           QUERY PLAN                           
+----------------------------------------------------------------
+ Bitmap Heap Scan on index_test
+   Recheck Cond: ((num = 50) AND (data > 'data 500'::text))
+   ->  Bitmap Index Scan on idx_multi
+         Index Cond: ((num = 50) AND (data > 'data 500'::text))
+(4 rows)
+
+ALTER INDEX idx_multi DISABLE;
+SELECT show_index_status('idx_multi');
+  show_index_status  
+---------------------
+ (idx_multi,t,t,t,f)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE num = 50 AND data > 'data 500';
+                      QUERY PLAN                      
+------------------------------------------------------
+ Seq Scan on index_test
+   Filter: ((data > 'data 500'::text) AND (num = 50))
+(2 rows)
+
+ALTER INDEX idx_multi ENABLE;
+SELECT show_index_status('idx_multi');
+  show_index_status  
+---------------------
+ (idx_multi,t,t,t,t)
+(1 row)
+
+-- 3. Partial index
+CREATE INDEX idx_partial ON index_test(num) WHERE num < 50;
+SELECT show_index_status('idx_partial');
+   show_index_status   
+-----------------------
+ (idx_partial,t,t,t,t)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE num = 25;
+               QUERY PLAN               
+----------------------------------------
+ Bitmap Heap Scan on index_test
+   Recheck Cond: (num = 25)
+   ->  Bitmap Index Scan on idx_partial
+         Index Cond: (num = 25)
+(4 rows)
+
+ALTER INDEX idx_partial DISABLE;
+SELECT show_index_status('idx_partial');
+   show_index_status   
+-----------------------
+ (idx_partial,t,t,t,f)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE num = 25;
+              QUERY PLAN              
+--------------------------------------
+ Bitmap Heap Scan on index_test
+   Recheck Cond: (num = 25)
+   ->  Bitmap Index Scan on idx_multi
+         Index Cond: (num = 25)
+(4 rows)
+
+ALTER INDEX idx_partial ENABLE;
+SELECT show_index_status('idx_partial');
+   show_index_status   
+-----------------------
+ (idx_partial,t,t,t,t)
+(1 row)
+
+-- 4. Expression index
+CREATE INDEX idx_expression ON index_test((lower(data)));
+SELECT show_index_status('idx_expression');
+    show_index_status     
+--------------------------
+ (idx_expression,t,t,t,t)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE lower(data) = 'data 500';
+                      QUERY PLAN                      
+------------------------------------------------------
+ Bitmap Heap Scan on index_test
+   Recheck Cond: (lower(data) = 'data 500'::text)
+   ->  Bitmap Index Scan on idx_expression
+         Index Cond: (lower(data) = 'data 500'::text)
+(4 rows)
+
+ALTER INDEX idx_expression DISABLE;
+SELECT show_index_status('idx_expression');
+    show_index_status     
+--------------------------
+ (idx_expression,t,t,t,f)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE lower(data) = 'data 500';
+                 QUERY PLAN                 
+--------------------------------------------
+ Seq Scan on index_test
+   Filter: (lower(data) = 'data 500'::text)
+(2 rows)
+
+ALTER INDEX idx_expression ENABLE;
+SELECT show_index_status('idx_expression');
+    show_index_status     
+--------------------------
+ (idx_expression,t,t,t,t)
+(1 row)
+
+-- 5. GIN index
+CREATE INDEX idx_gin ON index_test USING gin(vector);
+SELECT show_index_status('idx_gin');
+ show_index_status 
+-------------------
+ (idx_gin,t,t,t,t)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE vector @> ARRAY[500];
+                     QUERY PLAN                     
+----------------------------------------------------
+ Bitmap Heap Scan on index_test
+   Recheck Cond: (vector @> '{500}'::integer[])
+   ->  Bitmap Index Scan on idx_gin
+         Index Cond: (vector @> '{500}'::integer[])
+(4 rows)
+
+ALTER INDEX idx_gin DISABLE;
+SELECT show_index_status('idx_gin');
+ show_index_status 
+-------------------
+ (idx_gin,t,t,t,f)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE vector @> ARRAY[500];
+                QUERY PLAN                
+------------------------------------------
+ Seq Scan on index_test
+   Filter: (vector @> '{500}'::integer[])
+(2 rows)
+
+ALTER INDEX idx_gin ENABLE;
+SELECT show_index_status('idx_gin');
+ show_index_status 
+-------------------
+ (idx_gin,t,t,t,t)
+(1 row)
+
+-- 6. GiST index
+CREATE INDEX idx_gist ON index_test USING gist(range);
+SELECT show_index_status('idx_gist');
+ show_index_status  
+--------------------
+ (idx_gist,t,t,t,t)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE range && int4range(100, 110);
+                      QUERY PLAN                       
+-------------------------------------------------------
+ Bitmap Heap Scan on index_test
+   Recheck Cond: (range && '[100,110)'::int4range)
+   ->  Bitmap Index Scan on idx_gist
+         Index Cond: (range && '[100,110)'::int4range)
+(4 rows)
+
+ALTER INDEX idx_gist DISABLE;
+SELECT show_index_status('idx_gist');
+ show_index_status  
+--------------------
+ (idx_gist,t,t,t,f)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE range && int4range(100, 110);
+                 QUERY PLAN                  
+---------------------------------------------
+ Seq Scan on index_test
+   Filter: (range && '[100,110)'::int4range)
+(2 rows)
+
+ALTER INDEX idx_gist ENABLE;
+SELECT show_index_status('idx_gist');
+ show_index_status  
+--------------------
+ (idx_gist,t,t,t,t)
+(1 row)
+
+-- 7. Covering index
+CREATE INDEX idx_covering ON index_test(num) INCLUDE (data);
+SELECT show_index_status('idx_covering');
+   show_index_status    
+------------------------
+ (idx_covering,t,t,t,t)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT num, data FROM index_test WHERE num = 50;
+               QUERY PLAN                
+-----------------------------------------
+ Bitmap Heap Scan on index_test
+   Recheck Cond: (num = 50)
+   ->  Bitmap Index Scan on idx_covering
+         Index Cond: (num = 50)
+(4 rows)
+
+ALTER INDEX idx_covering DISABLE;
+SELECT show_index_status('idx_covering');
+   show_index_status    
+------------------------
+ (idx_covering,t,t,t,f)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT num, data FROM index_test WHERE num = 50;
+              QUERY PLAN              
+--------------------------------------
+ Bitmap Heap Scan on index_test
+   Recheck Cond: (num = 50)
+   ->  Bitmap Index Scan on idx_multi
+         Index Cond: (num = 50)
+(4 rows)
+
+ALTER INDEX idx_covering ENABLE;
+SELECT show_index_status('idx_covering');
+   show_index_status    
+------------------------
+ (idx_covering,t,t,t,t)
+(1 row)
+
+-- 8. Unique index
+CREATE UNIQUE INDEX idx_unique ON index_test(id, data);
+SELECT show_index_status('idx_unique');
+  show_index_status   
+----------------------
+ (idx_unique,t,t,t,t)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE id = 500 AND data = 'data 500';
+                        QUERY PLAN                        
+----------------------------------------------------------
+ Index Scan using idx_unique on index_test
+   Index Cond: ((id = 500) AND (data = 'data 500'::text))
+(2 rows)
+
+ALTER INDEX idx_unique DISABLE;
+SELECT show_index_status('idx_unique');
+  show_index_status   
+----------------------
+ (idx_unique,t,t,t,f)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE id = 500 AND data = 'data 500';
+                   QUERY PLAN                   
+------------------------------------------------
+ Index Scan using index_test_pkey on index_test
+   Index Cond: (id = 500)
+   Filter: (data = 'data 500'::text)
+(3 rows)
+
+ALTER INDEX idx_unique ENABLE;
+SELECT show_index_status('idx_unique');
+  show_index_status   
+----------------------
+ (idx_unique,t,t,t,t)
+(1 row)
+
+-- 9. Function-based index
+CREATE INDEX idx_func ON index_test(get_data_length(data));
+SELECT show_index_status('idx_func');
+ show_index_status  
+--------------------
+ (idx_func,t,t,t,t)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE get_data_length(data) = 10;
+               QUERY PLAN                
+-----------------------------------------
+ Bitmap Heap Scan on index_test
+   Recheck Cond: (length(data) = 10)
+   ->  Bitmap Index Scan on idx_func
+         Index Cond: (length(data) = 10)
+(4 rows)
+
+ALTER INDEX idx_func DISABLE;
+SELECT show_index_status('idx_func');
+ show_index_status  
+--------------------
+ (idx_func,t,t,t,f)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE get_data_length(data) = 10;
+          QUERY PLAN           
+-------------------------------
+ Seq Scan on index_test
+   Filter: (length(data) = 10)
+(2 rows)
+
+ALTER INDEX idx_func ENABLE;
+SELECT show_index_status('idx_func');
+ show_index_status  
+--------------------
+ (idx_func,t,t,t,t)
+(1 row)
+
+-- 10. Join index
+CREATE TABLE join_test (id INT PRIMARY KEY, ref_id INT);
+INSERT INTO join_test SELECT g, g % 100 FROM generate_series(1, 1000) g;
+CREATE INDEX idx_join ON join_test(ref_id);
+SELECT show_index_status('idx_join');
+ show_index_status  
+--------------------
+ (idx_join,t,t,t,t)
+(1 row)
+
+EXPLAIN (COSTS OFF)
+SELECT jt.id, it.data
+FROM join_test jt
+JOIN index_test it ON jt.ref_id = it.num
+WHERE jt.id BETWEEN 100 AND 200;
+                          QUERY PLAN                           
+---------------------------------------------------------------
+ Hash Join
+   Hash Cond: (it.num = jt.ref_id)
+   ->  Seq Scan on index_test it
+   ->  Hash
+         ->  Bitmap Heap Scan on join_test jt
+               Recheck Cond: ((id >= 100) AND (id <= 200))
+               ->  Bitmap Index Scan on join_test_pkey
+                     Index Cond: ((id >= 100) AND (id <= 200))
+(8 rows)
+
+-- Disable all indexes to force seq scan
+ALTER INDEX idx_join DISABLE;
+ALTER INDEX join_test_pkey DISABLE;
+SELECT show_index_status('idx_join');
+ show_index_status  
+--------------------
+ (idx_join,t,t,t,f)
+(1 row)
+
+SELECT show_index_status('join_test_pkey');
+    show_index_status     
+--------------------------
+ (join_test_pkey,t,t,t,f)
+(1 row)
+
+EXPLAIN (COSTS OFF)
+SELECT jt.id, it.data
+FROM join_test jt
+JOIN index_test it ON jt.ref_id = it.num
+WHERE jt.id BETWEEN 100 AND 200;
+                     QUERY PLAN                      
+-----------------------------------------------------
+ Hash Join
+   Hash Cond: (it.num = jt.ref_id)
+   ->  Seq Scan on index_test it
+   ->  Hash
+         ->  Seq Scan on join_test jt
+               Filter: ((id >= 100) AND (id <= 200))
+(6 rows)
+
+ALTER INDEX idx_join ENABLE;
+ALTER INDEX join_test_pkey ENABLE;
+SELECT show_index_status('idx_join');
+ show_index_status  
+--------------------
+ (idx_join,t,t,t,t)
+(1 row)
+
+SELECT show_index_status('join_test_pkey');
+    show_index_status     
+--------------------------
+ (join_test_pkey,t,t,t,t)
+(1 row)
+
+-- Test REINDEX CONCURRENTLY
+REINDEX INDEX CONCURRENTLY idx_join;
+SELECT show_index_status('idx_join');
+ show_index_status  
+--------------------
+ (idx_join,t,t,t,t)
+(1 row)
+
+ALTER INDEX idx_join DISABLE;
+SELECT show_index_status('idx_join');
+ show_index_status  
+--------------------
+ (idx_join,t,t,t,f)
+(1 row)
+
+REINDEX INDEX CONCURRENTLY idx_join;
+SELECT show_index_status('idx_join');
+ show_index_status  
+--------------------
+ (idx_join,t,t,t,f)
+(1 row)
+
+SELECT pg_get_indexdef('idx_join'::regclass);
+                                  pg_get_indexdef                                  
+-----------------------------------------------------------------------------------
+ CREATE INDEX idx_join ON schema_to_reindex.join_test USING btree (ref_id) DISABLE
+(1 row)
+
+ALTER INDEX idx_join ENABLE;
+SELECT pg_get_indexdef('idx_join'::regclass);
+                              pg_get_indexdef                              
+---------------------------------------------------------------------------
+ CREATE INDEX idx_join ON schema_to_reindex.join_test USING btree (ref_id)
+(1 row)
+
+-- Clean up
+DROP TABLE index_test;
+DROP TABLE join_test;
+DROP FUNCTION get_data_length;
+DROP FUNCTION show_index_status;
 -- Failure for unauthorized user
 CREATE ROLE regress_reindexuser NOLOGIN;
 SET SESSION ROLE regress_reindexuser;
diff --git a/src/test/regress/sql/create_index.sql b/src/test/regress/sql/create_index.sql
index fe162cc7c3..db547898aa 100644
--- a/src/test/regress/sql/create_index.sql
+++ b/src/test/regress/sql/create_index.sql
@@ -1297,6 +1297,187 @@ END;
 -- concurrently
 REINDEX SCHEMA CONCURRENTLY schema_to_reindex;
 
+-- Test enable/disable functionality for indexes
+
+-- Setup
+CREATE TABLE index_test(
+    id INT PRIMARY KEY,
+    data TEXT,
+    num INT,
+    vector INT[],
+    range INT4RANGE
+);
+
+INSERT INTO index_test
+SELECT
+    g,
+    'data ' || g,
+    g % 100,
+    ARRAY[g, g+1, g+2],
+    int4range(g, g+10)
+FROM generate_series(1, 1000) g;
+
+-- Function for testing
+CREATE FUNCTION get_data_length(text) RETURNS INT AS $$
+    SELECT length($1);
+$$ LANGUAGE SQL IMMUTABLE;
+
+-- Helper function to show index status
+CREATE OR REPLACE FUNCTION show_index_status(index_name text)
+RETURNS TABLE (
+    indexrelid regclass,
+    indisvalid boolean,
+    indisready boolean,
+    indislive boolean,
+    indisenabled boolean
+) AS $$
+BEGIN
+    RETURN QUERY EXECUTE format('
+        SELECT indexrelid::regclass, indisvalid, indisready, indislive, indisenabled
+        FROM pg_index
+        WHERE indexrelid = %L::regclass', index_name);
+END;
+$$ LANGUAGE plpgsql;
+
+-- Create and test each index type
+-- 1. Basic single-column index
+CREATE INDEX idx_single ON index_test(data);
+SELECT show_index_status('idx_single');
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE data = 'data 500';
+ALTER INDEX idx_single DISABLE;
+SELECT show_index_status('idx_single');
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE data = 'data 500';
+ALTER INDEX idx_single ENABLE;
+SELECT show_index_status('idx_single');
+
+-- 2. Multi-column index
+CREATE INDEX idx_multi ON index_test(num, data);
+SELECT show_index_status('idx_multi');
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE num = 50 AND data > 'data 500';
+ALTER INDEX idx_multi DISABLE;
+SELECT show_index_status('idx_multi');
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE num = 50 AND data > 'data 500';
+ALTER INDEX idx_multi ENABLE;
+SELECT show_index_status('idx_multi');
+
+-- 3. Partial index
+CREATE INDEX idx_partial ON index_test(num) WHERE num < 50;
+SELECT show_index_status('idx_partial');
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE num = 25;
+ALTER INDEX idx_partial DISABLE;
+SELECT show_index_status('idx_partial');
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE num = 25;
+ALTER INDEX idx_partial ENABLE;
+SELECT show_index_status('idx_partial');
+
+-- 4. Expression index
+CREATE INDEX idx_expression ON index_test((lower(data)));
+SELECT show_index_status('idx_expression');
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE lower(data) = 'data 500';
+ALTER INDEX idx_expression DISABLE;
+SELECT show_index_status('idx_expression');
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE lower(data) = 'data 500';
+ALTER INDEX idx_expression ENABLE;
+SELECT show_index_status('idx_expression');
+
+-- 5. GIN index
+CREATE INDEX idx_gin ON index_test USING gin(vector);
+SELECT show_index_status('idx_gin');
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE vector @> ARRAY[500];
+ALTER INDEX idx_gin DISABLE;
+SELECT show_index_status('idx_gin');
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE vector @> ARRAY[500];
+ALTER INDEX idx_gin ENABLE;
+SELECT show_index_status('idx_gin');
+
+-- 6. GiST index
+CREATE INDEX idx_gist ON index_test USING gist(range);
+SELECT show_index_status('idx_gist');
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE range && int4range(100, 110);
+ALTER INDEX idx_gist DISABLE;
+SELECT show_index_status('idx_gist');
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE range && int4range(100, 110);
+ALTER INDEX idx_gist ENABLE;
+SELECT show_index_status('idx_gist');
+
+-- 7. Covering index
+CREATE INDEX idx_covering ON index_test(num) INCLUDE (data);
+SELECT show_index_status('idx_covering');
+EXPLAIN (COSTS OFF) SELECT num, data FROM index_test WHERE num = 50;
+ALTER INDEX idx_covering DISABLE;
+SELECT show_index_status('idx_covering');
+EXPLAIN (COSTS OFF) SELECT num, data FROM index_test WHERE num = 50;
+ALTER INDEX idx_covering ENABLE;
+SELECT show_index_status('idx_covering');
+
+-- 8. Unique index
+CREATE UNIQUE INDEX idx_unique ON index_test(id, data);
+SELECT show_index_status('idx_unique');
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE id = 500 AND data = 'data 500';
+ALTER INDEX idx_unique DISABLE;
+SELECT show_index_status('idx_unique');
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE id = 500 AND data = 'data 500';
+ALTER INDEX idx_unique ENABLE;
+SELECT show_index_status('idx_unique');
+
+-- 9. Function-based index
+CREATE INDEX idx_func ON index_test(get_data_length(data));
+SELECT show_index_status('idx_func');
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE get_data_length(data) = 10;
+ALTER INDEX idx_func DISABLE;
+SELECT show_index_status('idx_func');
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE get_data_length(data) = 10;
+ALTER INDEX idx_func ENABLE;
+SELECT show_index_status('idx_func');
+
+-- 10. Join index
+CREATE TABLE join_test (id INT PRIMARY KEY, ref_id INT);
+INSERT INTO join_test SELECT g, g % 100 FROM generate_series(1, 1000) g;
+CREATE INDEX idx_join ON join_test(ref_id);
+SELECT show_index_status('idx_join');
+
+EXPLAIN (COSTS OFF)
+SELECT jt.id, it.data
+FROM join_test jt
+JOIN index_test it ON jt.ref_id = it.num
+WHERE jt.id BETWEEN 100 AND 200;
+
+-- Disable all indexes to force seq scan
+ALTER INDEX idx_join DISABLE;
+ALTER INDEX join_test_pkey DISABLE;
+SELECT show_index_status('idx_join');
+SELECT show_index_status('join_test_pkey');
+
+EXPLAIN (COSTS OFF)
+SELECT jt.id, it.data
+FROM join_test jt
+JOIN index_test it ON jt.ref_id = it.num
+WHERE jt.id BETWEEN 100 AND 200;
+
+ALTER INDEX idx_join ENABLE;
+ALTER INDEX join_test_pkey ENABLE;
+SELECT show_index_status('idx_join');
+SELECT show_index_status('join_test_pkey');
+
+-- Test REINDEX CONCURRENTLY
+REINDEX INDEX CONCURRENTLY idx_join;
+SELECT show_index_status('idx_join');
+
+ALTER INDEX idx_join DISABLE;
+SELECT show_index_status('idx_join');
+REINDEX INDEX CONCURRENTLY idx_join;
+SELECT show_index_status('idx_join');
+
+SELECT pg_get_indexdef('idx_join'::regclass);
+ALTER INDEX idx_join ENABLE;
+SELECT pg_get_indexdef('idx_join'::regclass);
+
+-- Clean up
+DROP TABLE index_test;
+DROP TABLE join_test;
+DROP FUNCTION get_data_length;
+DROP FUNCTION show_index_status;
+
 -- Failure for unauthorized user
 CREATE ROLE regress_reindexuser NOLOGIN;
 SET SESSION ROLE regress_reindexuser;
-- 
2.37.1 (Apple Git-137.1)

#41Shayon Mukherjee
shayonj@gmail.com
In reply to: Shayon Mukherjee (#40)
Re: Proposal to Enable/Disable Index using ALTER INDEX (with patch)

On Oct 16, 2024, at 2:15 PM, Shayon Mukherjee <shayonj@gmail.com> wrote:

On Oct 16, 2024, at 12:19 PM, Shayon Mukherjee <shayonj@gmail.com> wrote:

- ALTER INDEX ... ENABLE/DISABLE performs an in-place update of the pg_index
catalog to protect against indcheckxmin [2] (older unrelated thread).

Performing the in place update of the pg_index row from ATExecEnableDisableIndex using systable_inplace_update_begin was failing in CI weirdly but not on my local MacBook when running spec suite. I am also wondering what is causing the requirement [1] to update the row in-place vs say using CatalogTupleUpdate since using the later is working well locally + CI?

I believe I somewhat understand why the issue might be occurring, where CI is failing the create_index regression test and crashing (signal 6 in postmaster logs). I suspect it might be due to a segmentation fault or a similar issue.

IsInplaceUpdateOid is used in systable_inplace_update_begin (recently introduced), but it doesn’t yet support pg_index. Based on check_lock_if_inplace_updateable_rel in heapam.c and IsInplaceUpdateOid in catalog.c, introducing support for in-place updates via this new mechanism might not be straightforward for pg_index. It would require updating the callers to handle in-place updates and locks, I presume?

I did confirm that, based on the v2 PATCH, when not doing in-place updates on pg_index - it means that the xmin for pg_index would increment. I suppose there’s a risk of indcheckxmin being marked as TRUE when xmin exceeds, potentially causing an index to be accidentally skipped ? (I am not 100% sure)

I'll take some time to think this through and familiarize myself with the new systable_inplace_update_begin. In the meantime, aside from the in-place updates on pg_index, I would love to learn any first impressions or feedback on the patch folks may have.

Thank you,
Shayon

#42Shayon Mukherjee
shayonj@gmail.com
In reply to: Shayon Mukherjee (#41)
1 attachment(s)
Re: Proposal to Enable/Disable Index using ALTER INDEX (with patch)

On Oct 16, 2024, at 6:01 PM, Shayon Mukherjee <shayonj@gmail.com> wrote:

I'll take some time to think this through and familiarize myself with the
new systable_inplace_update_begin. In the meantime, aside from the in-place
updates on pg_index, I would love to learn any first impressions or
feedback on the patch folks may have.

My take away from whether or not an in-place update is needed on pg_index
[1]: /messages/by-id/20180618215635.m5vrnxdxhxytvmcm@alap3.anarazel.de

- It’s unclear to me why it’s needed.
- I understand the xmin would get incremented when using CatalogTupleUpdate
to update indisenabled.
- However, I haven’t been able to replicate any odd behavior locally or CI.
- FWIW - REINDEX CONCURRENTLY (via index_swap), index_constraint_create
and few other places perform CatalogTupleUpdate to update the relevant
attributes as well.

Based on the above summary and after my testing I would like to propose a
v3 of the patch. The only difference between this and v1 [2]/messages/by-id/EF2313B8-A017-4869-9B7F-A24EDD8795DE@gmail.com is that the
update of pg_index row happens via CatalogTupleUpdate.

[1]: /messages/by-id/20180618215635.m5vrnxdxhxytvmcm@alap3.anarazel.de
/messages/by-id/20180618215635.m5vrnxdxhxytvmcm@alap3.anarazel.de
[2]: /messages/by-id/EF2313B8-A017-4869-9B7F-A24EDD8795DE@gmail.com
/messages/by-id/EF2313B8-A017-4869-9B7F-A24EDD8795DE@gmail.com

Thank you for bearing with me on this :D
Shayon

Attachments:

v3-0001-Introduce-the-ability-to-enable-disable-indexes-u.patchapplication/octet-stream; name=v3-0001-Introduce-the-ability-to-enable-disable-indexes-u.patchDownload
From 7a1d058b264bb1f1aa50fef1b6b224b79893d716 Mon Sep 17 00:00:00 2001
From: Shayon Mukherjee <shayonj@gmail.com>
Date: Thu, 17 Oct 2024 09:38:06 -0400
Subject: [PATCH v3] Introduce the ability to enable/disable indexes using
 ALTER INDEX

This patch introduces the ability to enable or disable indexes using ALTER INDEX
and CREATE INDEX commands.

Original motivation for the problem and proposal for a patch
can be found at [1].

This patch passes all the existing specs and the newly added regression tests. The patch
is ready for review and test. It compiles, so the can patch can be applied for testing as well.

Implementation details:

- New Grammar:
  * ALTER INDEX ... ENABLE/DISABLE
  * CREATE INDEX ... DISABLE

- Default state is enabled. Indexes are only disabled when explicitly
  instructed via CREATE INDEX ... DISABLE or ALTER INDEX ... DISABLE.

- Primary Key and Unique constraint indexes are always enabled as well. The
  ENABLE/DISABLE grammar is not supported for these types of indexes. They can
  be later disabled via ALTER INDEX ... ENABLE/DISABLE.

- ALTER INDEX ... ENABLE/DISABLE performs update on the relevant row in pg_index
  catalog

- pg_get_indexdef() support the new functionality and grammar. This change is
  reflected in \d output for tables and pg_dump. We show the DISABLE syntax accordingly.

- Updated create_index.sql regression test to cover the new grammar and verify
  that disabled indexes are not used in queries. The test CATALOG_VERSION_NO

  - Basic single-column and multi-column indexes
  - Partial indexes
  - Expression indexes
  - Join indexes
  - GIN and GiST indexes
  - Covering indexes
  - Range indexes
  - Unique indexes and constraints

- Adds a new enabled attribute to the IndexOptInfo structure.

- Modifies get_relation_info in plancat.c to skip disabled indexes entirely, thus reducing the number of places we need to check if an index is disabled or not. Inspired by the conversations start at [2].
  - I chose to modify the logic within get_relation_info as compared to, say, reducing the cost to make the planner not consider an index during planning, mostly to keep the number of changes being introduced to a minimum and also the logic itself being self-contained and easier to under perhaps (?).

- No changes are made to stop the index from getting rebuilt. This way we ensure no
  data miss or corruption when index is re-nabled.

- TOAST indexes are supported and enabled by default as well.

- REINDEX CONCURRENTLY is supported as well and existing state of pg_index.indisenabled
  is carried over accordingly.

- See the changes in create_index.sql to get an idea of the grammar and sql statements.

- See the changes in create_index.out to get an idea of the catalogue states and EXPLAIN
  output to see when an index is getting used or isn't (when disabled).

- Incorporated DavidR's feedback from [3] around documentation and also you will see that by skip disabled indexes entirely from get_relation_info in plancat.c (as mentioned above), we address the other mentioned issues as well.

Looking forward to any and all feedback on this patch, including but not limited to code quality, tests, fundamental logic.

[1] https://www.postgresql.org/message-id/CANqtF-oXKe0M%3D0QOih6H%2BsZRjE2BWAbkW_1%2B9nMEAMLxUJg5jA%40mail.gmail.com
[2] https://www.postgresql.org/message-id/3465209.1727202064%40sss.pgh.pa.us
[3] https://www.postgresql.org/message-id/CAApHDvpUNu%3DiVcdJ74sypvgeaCF%2Btfpyb8VRhZaF7DTd1xVr7g%40mail.gmail.com
---
 doc/src/sgml/catalogs.sgml                 |  11 +
 doc/src/sgml/ref/alter_index.sgml          |  43 ++
 doc/src/sgml/ref/create_index.sgml         |  29 ++
 src/backend/bootstrap/bootparse.y          |   2 +
 src/backend/catalog/index.c                |  31 +-
 src/backend/catalog/toasting.c             |   2 +-
 src/backend/commands/indexcmds.c           |   4 +
 src/backend/commands/tablecmds.c           |  58 ++-
 src/backend/optimizer/util/plancat.c       |  13 +
 src/backend/parser/gram.y                  |  48 +-
 src/backend/parser/parse_utilcmd.c         |   3 +
 src/backend/utils/adt/ruleutils.c          |   4 +
 src/backend/utils/cache/relcache.c         |   1 +
 src/include/catalog/index.h                |   2 +-
 src/include/catalog/pg_index.h             |   1 +
 src/include/nodes/parsenodes.h             |   3 +
 src/include/nodes/pathnodes.h              |   2 +
 src/test/regress/expected/create_index.out | 494 +++++++++++++++++++++
 src/test/regress/sql/create_index.sql      | 181 ++++++++
 19 files changed, 922 insertions(+), 10 deletions(-)

diff --git a/doc/src/sgml/catalogs.sgml b/doc/src/sgml/catalogs.sgml
index 964c819a02..124ca3dc35 100644
--- a/doc/src/sgml/catalogs.sgml
+++ b/doc/src/sgml/catalogs.sgml
@@ -4590,6 +4590,17 @@ SCRAM-SHA-256$<replaceable>&lt;iteration count&gt;</replaceable>:<replaceable>&l
        partial index.
       </para></entry>
      </row>
+
+     <row>
+      <entry role="catalog_table_entry"><para role="column_definition">
+       <structfield>indisenabled</structfield> <type>bool</type>
+      </para>
+      <para>
+       If true, the index is currently enabled and should be used for queries.
+       If false, the index is disabled and should not be used for queries,
+       but is still maintained when the table is modified. Default is true.
+      </para></entry>
+     </row>
     </tbody>
    </tgroup>
   </table>
diff --git a/doc/src/sgml/ref/alter_index.sgml b/doc/src/sgml/ref/alter_index.sgml
index e26efec064..c5c13a3cb3 100644
--- a/doc/src/sgml/ref/alter_index.sgml
+++ b/doc/src/sgml/ref/alter_index.sgml
@@ -31,6 +31,8 @@ ALTER INDEX [ IF EXISTS ] <replaceable class="parameter">name</replaceable> ALTE
     SET STATISTICS <replaceable class="parameter">integer</replaceable>
 ALTER INDEX ALL IN TABLESPACE <replaceable class="parameter">name</replaceable> [ OWNED BY <replaceable class="parameter">role_name</replaceable> [, ... ] ]
     SET TABLESPACE <replaceable class="parameter">new_tablespace</replaceable> [ NOWAIT ]
+ALTER INDEX [ IF EXISTS ] <replaceable class="parameter">name</replaceable> ENABLE
+ALTER INDEX [ IF EXISTS ] <replaceable class="parameter">name</replaceable> DISABLE
 </synopsis>
  </refsynopsisdiv>
 
@@ -158,6 +160,33 @@ ALTER INDEX ALL IN TABLESPACE <replaceable class="parameter">name</replaceable>
     </listitem>
    </varlistentry>
 
+   <varlistentry>
+    <term><literal>ENABLE</literal></term>
+    <listitem>
+     <para>
+      Enable the specified index. The index will be used by the query planner
+      for query optimization. This is the default state for newly created indexes.
+     </para>
+    </listitem>
+   </varlistentry>
+
+   <varlistentry>
+    <term><literal>DISABLE</literal></term>
+    <listitem>
+     <para>
+      Disable the specified index. A disabled index is not used by the query planner
+      for query optimization, but it is still maintained when the underlying table
+      data changes. This can be useful for testing query performance with and without
+      specific indexes, temporarily reducing the overhead of index maintenance
+      during bulk data loading operations, or verifying an index is not being used
+      before dropping it. If performance degrades after disabling an index, it can be
+      easily re-enabled. Before disabling, it's recommended to check
+      <structname>pg_stat_user_indexes</structname>.<structfield>idx_scan</structfield>
+      to identify potentially unused indexes.
+     </para>
+    </listitem>
+   </varlistentry>
+
   </variablelist>
   </para>
 
@@ -300,6 +329,20 @@ CREATE INDEX coord_idx ON measured (x, y, (z + t));
 ALTER INDEX coord_idx ALTER COLUMN 3 SET STATISTICS 1000;
 </programlisting></para>
 
+  <para>
+   To enable an index:
+<programlisting>
+ALTER INDEX idx_name ENABLE;
+</programlisting>
+  </para>
+
+  <para>
+   To disable an index:
+<programlisting>
+ALTER INDEX idx_name DISABLE;
+</programlisting>
+  </para>
+
  </refsect1>
 
  <refsect1>
diff --git a/doc/src/sgml/ref/create_index.sgml b/doc/src/sgml/ref/create_index.sgml
index 621bc0e253..f1eebfa250 100644
--- a/doc/src/sgml/ref/create_index.sgml
+++ b/doc/src/sgml/ref/create_index.sgml
@@ -28,6 +28,7 @@ CREATE [ UNIQUE ] INDEX [ CONCURRENTLY ] [ [ IF NOT EXISTS ] <replaceable class=
     [ WITH ( <replaceable class="parameter">storage_parameter</replaceable> [= <replaceable class="parameter">value</replaceable>] [, ... ] ) ]
     [ TABLESPACE <replaceable class="parameter">tablespace_name</replaceable> ]
     [ WHERE <replaceable class="parameter">predicate</replaceable> ]
+    [ DISABLE ]
 </synopsis>
  </refsynopsisdiv>
 
@@ -380,6 +381,19 @@ CREATE [ UNIQUE ] INDEX [ CONCURRENTLY ] [ [ IF NOT EXISTS ] <replaceable class=
       </listitem>
      </varlistentry>
 
+    <varlistentry>
+      <term><literal>DISABLE</literal></term>
+      <listitem>
+       <para>
+        Creates the index in a disabled state (default enabled). A disabled index is not used by the
+        query planner for query optimization, but it is still maintained when the
+        underlying table data changes. This can be useful when you want to create
+        an index without immediately impacting query performance, allowing you to
+        enable it later at a more convenient time. The index can be enabled later
+        using <command>ALTER INDEX ... ENABLE</command>.
+       </para>
+      </listitem>
+     </varlistentry>
     </variablelist>
 
   <refsect2 id="sql-createindex-storage-parameters" xreflabel="Index Storage Parameters">
@@ -701,6 +715,14 @@ Indexes:
     partitioned index is a metadata only operation.
    </para>
 
+  <para>
+   When creating an index with the <literal>DISABLE</literal> option, the index
+   will be created but not used for query planning. This can be useful for
+   preparing an index in advance of its use, or for testing purposes. The index
+   will still be maintained as the table is modified, so it can be enabled
+   later without needing to be rebuilt. By default all new indexes are enabled.
+  </para>
+
   </refsect2>
  </refsect1>
 
@@ -980,6 +1002,13 @@ SELECT * FROM points
 CREATE INDEX CONCURRENTLY sales_quantity_index ON sales_table (quantity);
 </programlisting></para>
 
+  <para>
+   To create an index on the table <literal>test_table</literal> with the default
+   name, but have it initially disabled:
+<programlisting>
+CREATE INDEX ON test_table (col1) DISABLE;
+</programlisting>
+  </para>
  </refsect1>
 
  <refsect1>
diff --git a/src/backend/bootstrap/bootparse.y b/src/backend/bootstrap/bootparse.y
index 73a7592fb7..6023d58490 100644
--- a/src/backend/bootstrap/bootparse.y
+++ b/src/backend/bootstrap/bootparse.y
@@ -302,6 +302,7 @@ Boot_DeclareIndexStmt:
 					stmt->concurrent = false;
 					stmt->if_not_exists = false;
 					stmt->reset_default_tblspc = false;
+					stmt->isenabled = true;
 
 					/* locks and races need not concern us in bootstrap mode */
 					relationId = RangeVarGetRelid(stmt->relation, NoLock,
@@ -355,6 +356,7 @@ Boot_DeclareUniqueIndexStmt:
 					stmt->concurrent = false;
 					stmt->if_not_exists = false;
 					stmt->reset_default_tblspc = false;
+					stmt->isenabled = true;
 
 					/* locks and races need not concern us in bootstrap mode */
 					relationId = RangeVarGetRelid(stmt->relation, NoLock,
diff --git a/src/backend/catalog/index.c b/src/backend/catalog/index.c
index 12822d0b14..15773ebb13 100644
--- a/src/backend/catalog/index.c
+++ b/src/backend/catalog/index.c
@@ -118,7 +118,8 @@ static void UpdateIndexRelation(Oid indexoid, Oid heapoid,
 								bool isexclusion,
 								bool immediate,
 								bool isvalid,
-								bool isready);
+								bool isready,
+								bool isenabled);
 static void index_update_stats(Relation rel,
 							   bool hasindex,
 							   double reltuples);
@@ -569,7 +570,8 @@ UpdateIndexRelation(Oid indexoid,
 					bool isexclusion,
 					bool immediate,
 					bool isvalid,
-					bool isready)
+					bool isready,
+					bool isenabled)
 {
 	int2vector *indkey;
 	oidvector  *indcollation;
@@ -647,6 +649,7 @@ UpdateIndexRelation(Oid indexoid,
 	values[Anum_pg_index_indisready - 1] = BoolGetDatum(isready);
 	values[Anum_pg_index_indislive - 1] = BoolGetDatum(true);
 	values[Anum_pg_index_indisreplident - 1] = BoolGetDatum(false);
+	values[Anum_pg_index_indisenabled - 1] = BoolGetDatum(isenabled);
 	values[Anum_pg_index_indkey - 1] = PointerGetDatum(indkey);
 	values[Anum_pg_index_indcollation - 1] = PointerGetDatum(indcollation);
 	values[Anum_pg_index_indclass - 1] = PointerGetDatum(indclass);
@@ -712,6 +715,8 @@ UpdateIndexRelation(Oid indexoid,
  *			already exists.
  *		INDEX_CREATE_PARTITIONED:
  *			create a partitioned index (table must be partitioned)
+ *		INDEX_CREATE_DISABLED:
+*				create the index as disabled if instructed, defaults to being enabled.
  * constr_flags: flags passed to index_constraint_create
  *		(only if INDEX_CREATE_ADD_CONSTRAINT is set)
  * allow_system_table_mods: allow table to be a system catalog
@@ -757,6 +762,7 @@ index_create(Relation heapRelation,
 	bool		invalid = (flags & INDEX_CREATE_INVALID) != 0;
 	bool		concurrent = (flags & INDEX_CREATE_CONCURRENT) != 0;
 	bool		partitioned = (flags & INDEX_CREATE_PARTITIONED) != 0;
+	bool 		isenabled  = (flags & INDEX_CREATE_ENABLED) != 0;
 	char		relkind;
 	TransactionId relfrozenxid;
 	MultiXactId relminmxid;
@@ -1040,13 +1046,15 @@ index_create(Relation heapRelation,
 	 *	  (Or, could define a rule to maintain the predicate) --Nels, Feb '92
 	 * ----------------
 	 */
+
 	UpdateIndexRelation(indexRelationId, heapRelationId, parentIndexRelid,
 						indexInfo,
 						collationIds, opclassIds, coloptions,
 						isprimary, is_exclusion,
 						(constr_flags & INDEX_CONSTR_CREATE_DEFERRABLE) == 0,
 						!concurrent && !invalid,
-						!concurrent);
+						!concurrent,
+						isenabled);
 
 	/*
 	 * Register relcache invalidation on the indexes' heap relation, to
@@ -1315,6 +1323,8 @@ index_concurrently_create_copy(Relation heapRelation, Oid oldIndexId,
 	List	   *indexColNames = NIL;
 	List	   *indexExprs = NIL;
 	List	   *indexPreds = NIL;
+	Form_pg_index indexForm;
+	bits16 	 createFlags;
 
 	indexRelation = index_open(oldIndexId, RowExclusiveLock);
 
@@ -1342,6 +1352,9 @@ index_concurrently_create_copy(Relation heapRelation, Oid oldIndexId,
 											Anum_pg_index_indoption);
 	indcoloptions = (int2vector *) DatumGetPointer(colOptionDatum);
 
+	/* Get the enabled state of the original index */
+	indexForm = (Form_pg_index) GETSTRUCT(indexTuple);
+
 	/* Fetch reloptions of index if any */
 	classTuple = SearchSysCache1(RELOID, ObjectIdGetDatum(oldIndexId));
 	if (!HeapTupleIsValid(classTuple))
@@ -1433,6 +1446,16 @@ index_concurrently_create_copy(Relation heapRelation, Oid oldIndexId,
 		stattargets[i].isnull = isnull;
 	}
 
+	/*
+	* Determine the create flags for the new index.
+	* We always use SKIP_BUILD and CONCURRENT for concurrent reindexing.
+	* If the original index was enabled, we also set the ENABLED flag
+	* to maintain the same state in the new index.
+	*/
+	createFlags = INDEX_CREATE_SKIP_BUILD | INDEX_CREATE_CONCURRENT;
+	if (indexForm->indisenabled)
+			createFlags |= INDEX_CREATE_ENABLED;
+
 	/*
 	 * Now create the new index.
 	 *
@@ -1456,7 +1479,7 @@ index_concurrently_create_copy(Relation heapRelation, Oid oldIndexId,
 							  indcoloptions->values,
 							  stattargets,
 							  reloptionsDatum,
-							  INDEX_CREATE_SKIP_BUILD | INDEX_CREATE_CONCURRENT,
+							  createFlags,
 							  0,
 							  true, /* allow table to be a system catalog? */
 							  false,	/* is_internal? */
diff --git a/src/backend/catalog/toasting.c b/src/backend/catalog/toasting.c
index ad3082c62a..dead993a74 100644
--- a/src/backend/catalog/toasting.c
+++ b/src/backend/catalog/toasting.c
@@ -325,7 +325,7 @@ create_toast_table(Relation rel, Oid toastOid, Oid toastIndexOid,
 				 BTREE_AM_OID,
 				 rel->rd_rel->reltablespace,
 				 collationIds, opclassIds, NULL, coloptions, NULL, (Datum) 0,
-				 INDEX_CREATE_IS_PRIMARY, 0, true, true, NULL);
+				 INDEX_CREATE_IS_PRIMARY | INDEX_CREATE_ENABLED, 0, true, true, NULL);
 
 	table_close(toast_rel, NoLock);
 
diff --git a/src/backend/commands/indexcmds.c b/src/backend/commands/indexcmds.c
index e33ad81529..d0604e9a00 100644
--- a/src/backend/commands/indexcmds.c
+++ b/src/backend/commands/indexcmds.c
@@ -1192,6 +1192,10 @@ DefineIndex(Oid tableId,
 		flags |= INDEX_CREATE_PARTITIONED;
 	if (stmt->primary)
 		flags |= INDEX_CREATE_IS_PRIMARY;
+   if (stmt->isenabled)
+		flags |= INDEX_CREATE_ENABLED;
+   else
+		flags &= ~INDEX_CREATE_ENABLED;
 
 	/*
 	 * If the table is partitioned, and recursion was declined but partitions
diff --git a/src/backend/commands/tablecmds.c b/src/backend/commands/tablecmds.c
index 1ccc80087c..7ccd15b06d 100644
--- a/src/backend/commands/tablecmds.c
+++ b/src/backend/commands/tablecmds.c
@@ -664,7 +664,7 @@ static List *GetParentedForeignKeyRefs(Relation partition);
 static void ATDetachCheckNoForeignKeyRefs(Relation partition);
 static char GetAttributeCompression(Oid atttypid, const char *compression);
 static char GetAttributeStorage(Oid atttypid, const char *storagemode);
-
+static void ATExecEnableDisableIndex(Relation rel, bool enable);
 
 /* ----------------------------------------------------------------
  *		DefineRelation
@@ -4558,6 +4558,8 @@ AlterTableGetLockLevel(List *cmds)
 			case AT_SetExpression:
 			case AT_DropExpression:
 			case AT_SetCompression:
+			case AT_EnableIndex:
+			case AT_DisableIndex:
 				cmd_lockmode = AccessExclusiveLock;
 				break;
 
@@ -5131,6 +5133,12 @@ ATPrepCmd(List **wqueue, Relation rel, AlterTableCmd *cmd,
 			/* No command-specific prep needed */
 			pass = AT_PASS_MISC;
 			break;
+		case AT_EnableIndex:
+		case AT_DisableIndex:
+			ATSimplePermissions(cmd->subtype, rel, ATT_INDEX | ATT_PARTITIONED_INDEX);
+			/* No command-specific prep needed */
+			pass = AT_PASS_MISC;
+			break;
 		default:				/* oops */
 			elog(ERROR, "unrecognized alter table type: %d",
 				 (int) cmd->subtype);
@@ -5527,6 +5535,12 @@ ATExecCmd(List **wqueue, AlteredTableInfo *tab,
 		case AT_DetachPartitionFinalize:
 			address = ATExecDetachPartitionFinalize(rel, ((PartitionCmd *) cmd->def)->name);
 			break;
+		case AT_EnableIndex:
+				ATExecEnableDisableIndex(rel, true);
+				break;
+		case AT_DisableIndex:
+				ATExecEnableDisableIndex(rel, false);
+				break;
 		default:				/* oops */
 			elog(ERROR, "unrecognized alter table type: %d",
 				 (int) cmd->subtype);
@@ -6426,6 +6440,8 @@ alter_table_type_to_string(AlterTableType cmdtype)
 			return "DROP COLUMN";
 		case AT_AddIndex:
 		case AT_ReAddIndex:
+		case AT_EnableIndex:
+		case AT_DisableIndex:
 			return NULL;		/* not real grammar */
 		case AT_AddConstraint:
 		case AT_ReAddConstraint:
@@ -20203,3 +20219,43 @@ GetAttributeStorage(Oid atttypid, const char *storagemode)
 
 	return cstorage;
 }
+
+/*
+ * ATExecEnableDisableIndex
+ * Performs a catalog update to enable or disable an index in pg_index.
+ */
+static void
+ATExecEnableDisableIndex(Relation rel, bool enable)
+{
+	Oid         indexOid = RelationGetRelid(rel);
+	Relation    pg_index;
+	HeapTuple   indexTuple;
+	Form_pg_index indexForm;
+	bool        updated = false;
+
+	pg_index = table_open(IndexRelationId, RowExclusiveLock);
+
+	indexTuple = SearchSysCacheCopy1(INDEXRELID, ObjectIdGetDatum(indexOid));
+	if (!HeapTupleIsValid(indexTuple))
+		elog(ERROR, "could not find tuple for index %u", indexOid);
+
+	indexForm = (Form_pg_index) GETSTRUCT(indexTuple);
+
+	if (indexForm->indisenabled != enable)
+	{
+		indexForm->indisenabled = enable;
+
+		CatalogTupleUpdate(pg_index, &indexTuple->t_self, indexTuple);
+		updated = true;
+	}
+
+	heap_freetuple(indexTuple);
+	table_close(pg_index, RowExclusiveLock);
+
+	if (updated)
+	{
+		CacheInvalidateRelcache(rel);
+		InvokeObjectPostAlterHook(IndexRelationId, indexOid, 0);
+		CommandCounterIncrement();
+	}
+}
diff --git a/src/backend/optimizer/util/plancat.c b/src/backend/optimizer/util/plancat.c
index b913f91ff0..eaa15a1f53 100644
--- a/src/backend/optimizer/util/plancat.c
+++ b/src/backend/optimizer/util/plancat.c
@@ -295,6 +295,19 @@ get_relation_info(PlannerInfo *root, Oid relationObjectId, bool inhparent,
 			info->opcintype = (Oid *) palloc(sizeof(Oid) * nkeycolumns);
 			info->canreturn = (bool *) palloc(sizeof(bool) * ncolumns);
 
+			/*
+			 * Skip disabled indexes altogether, as they should not be considered
+			 * for query planning. This builds the data structure for the planner's
+			 * use and we make it part of IndexOptInfo since the index is already open.
+			 * We also close the relation before continuing to the next index.
+			 */
+			info->enabled = index->indisenabled;
+			if (!info->enabled)
+			{
+				index_close(indexRelation, NoLock);
+				continue;
+			}
+
 			for (i = 0; i < ncolumns; i++)
 			{
 				info->indexkeys[i] = index->indkey.values[i];
diff --git a/src/backend/parser/gram.y b/src/backend/parser/gram.y
index 4aa8646af7..c5d0d66445 100644
--- a/src/backend/parser/gram.y
+++ b/src/backend/parser/gram.y
@@ -333,7 +333,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 %type <ival>	add_drop opt_asc_desc opt_nulls_order
 
 %type <node>	alter_table_cmd alter_type_cmd opt_collate_clause
-	   replica_identity partition_cmd index_partition_cmd
+	   replica_identity partition_cmd index_partition_cmd index_alter_cmd
 %type <list>	alter_table_cmds alter_type_cmds
 %type <list>    alter_identity_column_option_list
 %type <defelt>  alter_identity_column_option
@@ -496,6 +496,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 %type <boolean> opt_unique opt_verbose opt_full
 %type <boolean> opt_freeze opt_analyze opt_default
 %type <defelt>	opt_binary copy_delimiter
+%type <boolean>  opt_index_enabled
 
 %type <boolean> copy_from opt_program
 
@@ -2168,6 +2169,24 @@ AlterTableStmt:
 					n->nowait = $13;
 					$$ = (Node *) n;
 				}
+		| ALTER INDEX qualified_name index_alter_cmd
+				{
+					AlterTableStmt *n = makeNode(AlterTableStmt);
+					n->relation = $3;
+					n->cmds = list_make1($4);
+					n->objtype = OBJECT_INDEX;
+					n->missing_ok = false;
+					$$ = (Node *) n;
+				}
+		| ALTER INDEX IF_P EXISTS qualified_name index_alter_cmd
+				{
+					AlterTableStmt *n = makeNode(AlterTableStmt);
+					n->relation = $5;
+					n->cmds = list_make1($6);
+					n->objtype = OBJECT_INDEX;
+					n->missing_ok = true;
+					$$ = (Node *) n;
+				}
 		|	ALTER INDEX qualified_name alter_table_cmds
 				{
 					AlterTableStmt *n = makeNode(AlterTableStmt);
@@ -2393,6 +2412,21 @@ index_partition_cmd:
 				}
 		;
 
+index_alter_cmd:
+		/* ALTER INDEX <name> ENABLE|DISABLE */
+		ENABLE_P
+			{
+				AlterTableCmd *n = makeNode(AlterTableCmd);
+				n->subtype = AT_EnableIndex;
+				$$ = (Node *) n;
+			}
+		| DISABLE_P
+			{
+				AlterTableCmd *n = makeNode(AlterTableCmd);
+				n->subtype = AT_DisableIndex;
+				$$ = (Node *) n;
+			}
+		;
 alter_table_cmd:
 			/* ALTER TABLE <name> ADD <coldef> */
 			ADD_P columnDef
@@ -8126,7 +8160,7 @@ defacl_privilege_target:
 
 IndexStmt:	CREATE opt_unique INDEX opt_concurrently opt_single_name
 			ON relation_expr access_method_clause '(' index_params ')'
-			opt_include opt_unique_null_treatment opt_reloptions OptTableSpace where_clause
+			opt_include opt_unique_null_treatment opt_reloptions OptTableSpace where_clause opt_index_enabled
 				{
 					IndexStmt *n = makeNode(IndexStmt);
 
@@ -8141,6 +8175,7 @@ IndexStmt:	CREATE opt_unique INDEX opt_concurrently opt_single_name
 					n->options = $14;
 					n->tableSpace = $15;
 					n->whereClause = $16;
+					n->isenabled = $17;
 					n->excludeOpNames = NIL;
 					n->idxcomment = NULL;
 					n->indexOid = InvalidOid;
@@ -8158,7 +8193,7 @@ IndexStmt:	CREATE opt_unique INDEX opt_concurrently opt_single_name
 				}
 			| CREATE opt_unique INDEX opt_concurrently IF_P NOT EXISTS name
 			ON relation_expr access_method_clause '(' index_params ')'
-			opt_include opt_unique_null_treatment opt_reloptions OptTableSpace where_clause
+			opt_include opt_unique_null_treatment opt_reloptions OptTableSpace where_clause opt_index_enabled
 				{
 					IndexStmt *n = makeNode(IndexStmt);
 
@@ -8173,6 +8208,7 @@ IndexStmt:	CREATE opt_unique INDEX opt_concurrently opt_single_name
 					n->options = $17;
 					n->tableSpace = $18;
 					n->whereClause = $19;
+					n->isenabled = $20;
 					n->excludeOpNames = NIL;
 					n->idxcomment = NULL;
 					n->indexOid = InvalidOid;
@@ -8195,6 +8231,12 @@ opt_unique:
 			| /*EMPTY*/								{ $$ = false; }
 		;
 
+opt_index_enabled:
+			ENABLE_P                      { $$ = true; }
+			| DISABLE_P                   { $$ = false; }
+			| /*EMPTY*/                 	{ $$ = true; }
+		;
+
 access_method_clause:
 			USING name								{ $$ = $2; }
 			| /*EMPTY*/								{ $$ = DEFAULT_INDEX_TYPE; }
diff --git a/src/backend/parser/parse_utilcmd.c b/src/backend/parser/parse_utilcmd.c
index 1e15ce10b4..32554612ed 100644
--- a/src/backend/parser/parse_utilcmd.c
+++ b/src/backend/parser/parse_utilcmd.c
@@ -1588,6 +1588,7 @@ generateClonedIndexStmt(RangeVar *heapRel, Relation source_idx,
 	index->concurrent = false;
 	index->if_not_exists = false;
 	index->reset_default_tblspc = false;
+	index->isenabled = idxrec->indisenabled;
 
 	/*
 	 * We don't try to preserve the name of the source index; instead, just
@@ -2214,6 +2215,8 @@ transformIndexConstraint(Constraint *constraint, CreateStmtContext *cxt)
 	index->concurrent = false;
 	index->if_not_exists = false;
 	index->reset_default_tblspc = constraint->reset_default_tblspc;
+	/* Ensure indexes for constraints are created as enabled by default */
+	index->isenabled = true;
 
 	/*
 	 * If it's ALTER TABLE ADD CONSTRAINT USING INDEX, look up the index and
diff --git a/src/backend/utils/adt/ruleutils.c b/src/backend/utils/adt/ruleutils.c
index 2177d17e27..05b27ca232 100644
--- a/src/backend/utils/adt/ruleutils.c
+++ b/src/backend/utils/adt/ruleutils.c
@@ -1559,6 +1559,10 @@ pg_get_indexdef_worker(Oid indexrelid, int colno,
 			else
 				appendStringInfo(&buf, " WHERE %s", str);
 		}
+
+		/* Add DISABLE clause if the index is disabled */
+		if (!idxrec->indisenabled)
+				appendStringInfoString(&buf, " DISABLE");
 	}
 
 	/* Clean up */
diff --git a/src/backend/utils/cache/relcache.c b/src/backend/utils/cache/relcache.c
index c326f687eb..b3b43df080 100644
--- a/src/backend/utils/cache/relcache.c
+++ b/src/backend/utils/cache/relcache.c
@@ -2344,6 +2344,7 @@ RelationReloadIndexInfo(Relation relation)
 		relation->rd_index->indisready = index->indisready;
 		relation->rd_index->indislive = index->indislive;
 		relation->rd_index->indisreplident = index->indisreplident;
+		relation->rd_index->indisenabled = index->indisenabled;
 
 		/* Copy xmin too, as that is needed to make sense of indcheckxmin */
 		HeapTupleHeaderSetXmin(relation->rd_indextuple->t_data,
diff --git a/src/include/catalog/index.h b/src/include/catalog/index.h
index 2dea96f47c..8a47cfd174 100644
--- a/src/include/catalog/index.h
+++ b/src/include/catalog/index.h
@@ -65,6 +65,7 @@ extern void index_check_primary_key(Relation heapRel,
 #define	INDEX_CREATE_IF_NOT_EXISTS			(1 << 4)
 #define	INDEX_CREATE_PARTITIONED			(1 << 5)
 #define INDEX_CREATE_INVALID				(1 << 6)
+#define INDEX_CREATE_ENABLED        (1 << 7)
 
 extern Oid	index_create(Relation heapRelation,
 						 const char *indexRelationName,
@@ -175,7 +176,6 @@ extern void RestoreReindexState(const void *reindexstate);
 
 extern void IndexSetParentIndex(Relation partitionIdx, Oid parentOid);
 
-
 /*
  * itemptr_encode - Encode ItemPointer as int64/int8
  *
diff --git a/src/include/catalog/pg_index.h b/src/include/catalog/pg_index.h
index 6c89639a9e..b0c7e5f365 100644
--- a/src/include/catalog/pg_index.h
+++ b/src/include/catalog/pg_index.h
@@ -44,6 +44,7 @@ CATALOG(pg_index,2610,IndexRelationId) BKI_SCHEMA_MACRO
 	bool		indisready;		/* is this index ready for inserts? */
 	bool		indislive;		/* is this index alive at all? */
 	bool		indisreplident; /* is this index the identity for replication? */
+	bool		indisenabled;	/* is this index enabled for use by queries? */
 
 	/* variable-length fields start here, but we allow direct access to indkey */
 	int2vector	indkey BKI_FORCE_NOT_NULL;	/* column numbers of indexed cols,
diff --git a/src/include/nodes/parsenodes.h b/src/include/nodes/parsenodes.h
index c92cef3d16..8b85e91985 100644
--- a/src/include/nodes/parsenodes.h
+++ b/src/include/nodes/parsenodes.h
@@ -2414,6 +2414,8 @@ typedef enum AlterTableType
 	AT_SetIdentity,				/* SET identity column options */
 	AT_DropIdentity,			/* DROP IDENTITY */
 	AT_ReAddStatistics,			/* internal to commands/tablecmds.c */
+	AT_EnableIndex,					/* ENABLE INDEX */
+	AT_DisableIndex,				/* DISABLE INDEX */
 } AlterTableType;
 
 typedef struct ReplicaIdentityStmt
@@ -3392,6 +3394,7 @@ typedef struct IndexStmt
 	bool		if_not_exists;	/* just do nothing if index already exists? */
 	bool		reset_default_tblspc;	/* reset default_tablespace prior to
 										 * executing */
+  bool		isenabled;		/* true if ENABLE (default), false if DISABLE */
 } IndexStmt;
 
 /* ----------------------
diff --git a/src/include/nodes/pathnodes.h b/src/include/nodes/pathnodes.h
index 07e2415398..67a4d80d92 100644
--- a/src/include/nodes/pathnodes.h
+++ b/src/include/nodes/pathnodes.h
@@ -1207,6 +1207,8 @@ struct IndexOptInfo
 	/* AM's cost estimator */
 	/* Rather than include amapi.h here, we declare amcostestimate like this */
 	void		(*amcostestimate) () pg_node_attr(read_write_ignore);
+	/* true if this index is enabled */
+	bool		enabled;
 };
 
 /*
diff --git a/src/test/regress/expected/create_index.out b/src/test/regress/expected/create_index.out
index d3358dfc39..22513ae978 100644
--- a/src/test/regress/expected/create_index.out
+++ b/src/test/regress/expected/create_index.out
@@ -2965,6 +2965,500 @@ ERROR:  REINDEX SCHEMA cannot run inside a transaction block
 END;
 -- concurrently
 REINDEX SCHEMA CONCURRENTLY schema_to_reindex;
+-- Test enable/disable functionality for indexes
+-- Setup
+CREATE TABLE index_test(
+    id INT PRIMARY KEY,
+    data TEXT,
+    num INT,
+    vector INT[],
+    range INT4RANGE
+);
+INSERT INTO index_test
+SELECT
+    g,
+    'data ' || g,
+    g % 100,
+    ARRAY[g, g+1, g+2],
+    int4range(g, g+10)
+FROM generate_series(1, 1000) g;
+-- Function for testing
+CREATE FUNCTION get_data_length(text) RETURNS INT AS $$
+    SELECT length($1);
+$$ LANGUAGE SQL IMMUTABLE;
+-- Helper function to show index status
+CREATE OR REPLACE FUNCTION show_index_status(index_name text)
+RETURNS TABLE (
+    indexrelid regclass,
+    indisvalid boolean,
+    indisready boolean,
+    indislive boolean,
+    indisenabled boolean
+) AS $$
+BEGIN
+    RETURN QUERY EXECUTE format('
+        SELECT indexrelid::regclass, indisvalid, indisready, indislive, indisenabled
+        FROM pg_index
+        WHERE indexrelid = %L::regclass', index_name);
+END;
+$$ LANGUAGE plpgsql;
+-- Create and test each index type
+-- 1. Basic single-column index
+CREATE INDEX idx_single ON index_test(data);
+SELECT show_index_status('idx_single');
+  show_index_status   
+----------------------
+ (idx_single,t,t,t,t)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE data = 'data 500';
+                  QUERY PLAN                   
+-----------------------------------------------
+ Bitmap Heap Scan on index_test
+   Recheck Cond: (data = 'data 500'::text)
+   ->  Bitmap Index Scan on idx_single
+         Index Cond: (data = 'data 500'::text)
+(4 rows)
+
+ALTER INDEX idx_single DISABLE;
+SELECT show_index_status('idx_single');
+  show_index_status   
+----------------------
+ (idx_single,t,t,t,f)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE data = 'data 500';
+             QUERY PLAN              
+-------------------------------------
+ Seq Scan on index_test
+   Filter: (data = 'data 500'::text)
+(2 rows)
+
+ALTER INDEX idx_single ENABLE;
+SELECT show_index_status('idx_single');
+  show_index_status   
+----------------------
+ (idx_single,t,t,t,t)
+(1 row)
+
+-- 2. Multi-column index
+CREATE INDEX idx_multi ON index_test(num, data);
+SELECT show_index_status('idx_multi');
+  show_index_status  
+---------------------
+ (idx_multi,t,t,t,t)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE num = 50 AND data > 'data 500';
+                           QUERY PLAN                           
+----------------------------------------------------------------
+ Bitmap Heap Scan on index_test
+   Recheck Cond: ((num = 50) AND (data > 'data 500'::text))
+   ->  Bitmap Index Scan on idx_multi
+         Index Cond: ((num = 50) AND (data > 'data 500'::text))
+(4 rows)
+
+ALTER INDEX idx_multi DISABLE;
+SELECT show_index_status('idx_multi');
+  show_index_status  
+---------------------
+ (idx_multi,t,t,t,f)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE num = 50 AND data > 'data 500';
+                      QUERY PLAN                      
+------------------------------------------------------
+ Seq Scan on index_test
+   Filter: ((data > 'data 500'::text) AND (num = 50))
+(2 rows)
+
+ALTER INDEX idx_multi ENABLE;
+SELECT show_index_status('idx_multi');
+  show_index_status  
+---------------------
+ (idx_multi,t,t,t,t)
+(1 row)
+
+-- 3. Partial index
+CREATE INDEX idx_partial ON index_test(num) WHERE num < 50;
+SELECT show_index_status('idx_partial');
+   show_index_status   
+-----------------------
+ (idx_partial,t,t,t,t)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE num = 25;
+               QUERY PLAN               
+----------------------------------------
+ Bitmap Heap Scan on index_test
+   Recheck Cond: (num = 25)
+   ->  Bitmap Index Scan on idx_partial
+         Index Cond: (num = 25)
+(4 rows)
+
+ALTER INDEX idx_partial DISABLE;
+SELECT show_index_status('idx_partial');
+   show_index_status   
+-----------------------
+ (idx_partial,t,t,t,f)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE num = 25;
+              QUERY PLAN              
+--------------------------------------
+ Bitmap Heap Scan on index_test
+   Recheck Cond: (num = 25)
+   ->  Bitmap Index Scan on idx_multi
+         Index Cond: (num = 25)
+(4 rows)
+
+ALTER INDEX idx_partial ENABLE;
+SELECT show_index_status('idx_partial');
+   show_index_status   
+-----------------------
+ (idx_partial,t,t,t,t)
+(1 row)
+
+-- 4. Expression index
+CREATE INDEX idx_expression ON index_test((lower(data)));
+SELECT show_index_status('idx_expression');
+    show_index_status     
+--------------------------
+ (idx_expression,t,t,t,t)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE lower(data) = 'data 500';
+                      QUERY PLAN                      
+------------------------------------------------------
+ Bitmap Heap Scan on index_test
+   Recheck Cond: (lower(data) = 'data 500'::text)
+   ->  Bitmap Index Scan on idx_expression
+         Index Cond: (lower(data) = 'data 500'::text)
+(4 rows)
+
+ALTER INDEX idx_expression DISABLE;
+SELECT show_index_status('idx_expression');
+    show_index_status     
+--------------------------
+ (idx_expression,t,t,t,f)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE lower(data) = 'data 500';
+                 QUERY PLAN                 
+--------------------------------------------
+ Seq Scan on index_test
+   Filter: (lower(data) = 'data 500'::text)
+(2 rows)
+
+ALTER INDEX idx_expression ENABLE;
+SELECT show_index_status('idx_expression');
+    show_index_status     
+--------------------------
+ (idx_expression,t,t,t,t)
+(1 row)
+
+-- 5. GIN index
+CREATE INDEX idx_gin ON index_test USING gin(vector);
+SELECT show_index_status('idx_gin');
+ show_index_status 
+-------------------
+ (idx_gin,t,t,t,t)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE vector @> ARRAY[500];
+                     QUERY PLAN                     
+----------------------------------------------------
+ Bitmap Heap Scan on index_test
+   Recheck Cond: (vector @> '{500}'::integer[])
+   ->  Bitmap Index Scan on idx_gin
+         Index Cond: (vector @> '{500}'::integer[])
+(4 rows)
+
+ALTER INDEX idx_gin DISABLE;
+SELECT show_index_status('idx_gin');
+ show_index_status 
+-------------------
+ (idx_gin,t,t,t,f)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE vector @> ARRAY[500];
+                QUERY PLAN                
+------------------------------------------
+ Seq Scan on index_test
+   Filter: (vector @> '{500}'::integer[])
+(2 rows)
+
+ALTER INDEX idx_gin ENABLE;
+SELECT show_index_status('idx_gin');
+ show_index_status 
+-------------------
+ (idx_gin,t,t,t,t)
+(1 row)
+
+-- 6. GiST index
+CREATE INDEX idx_gist ON index_test USING gist(range);
+SELECT show_index_status('idx_gist');
+ show_index_status  
+--------------------
+ (idx_gist,t,t,t,t)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE range && int4range(100, 110);
+                      QUERY PLAN                       
+-------------------------------------------------------
+ Bitmap Heap Scan on index_test
+   Recheck Cond: (range && '[100,110)'::int4range)
+   ->  Bitmap Index Scan on idx_gist
+         Index Cond: (range && '[100,110)'::int4range)
+(4 rows)
+
+ALTER INDEX idx_gist DISABLE;
+SELECT show_index_status('idx_gist');
+ show_index_status  
+--------------------
+ (idx_gist,t,t,t,f)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE range && int4range(100, 110);
+                 QUERY PLAN                  
+---------------------------------------------
+ Seq Scan on index_test
+   Filter: (range && '[100,110)'::int4range)
+(2 rows)
+
+ALTER INDEX idx_gist ENABLE;
+SELECT show_index_status('idx_gist');
+ show_index_status  
+--------------------
+ (idx_gist,t,t,t,t)
+(1 row)
+
+-- 7. Covering index
+CREATE INDEX idx_covering ON index_test(num) INCLUDE (data);
+SELECT show_index_status('idx_covering');
+   show_index_status    
+------------------------
+ (idx_covering,t,t,t,t)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT num, data FROM index_test WHERE num = 50;
+               QUERY PLAN                
+-----------------------------------------
+ Bitmap Heap Scan on index_test
+   Recheck Cond: (num = 50)
+   ->  Bitmap Index Scan on idx_covering
+         Index Cond: (num = 50)
+(4 rows)
+
+ALTER INDEX idx_covering DISABLE;
+SELECT show_index_status('idx_covering');
+   show_index_status    
+------------------------
+ (idx_covering,t,t,t,f)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT num, data FROM index_test WHERE num = 50;
+              QUERY PLAN              
+--------------------------------------
+ Bitmap Heap Scan on index_test
+   Recheck Cond: (num = 50)
+   ->  Bitmap Index Scan on idx_multi
+         Index Cond: (num = 50)
+(4 rows)
+
+ALTER INDEX idx_covering ENABLE;
+SELECT show_index_status('idx_covering');
+   show_index_status    
+------------------------
+ (idx_covering,t,t,t,t)
+(1 row)
+
+-- 8. Unique index
+CREATE UNIQUE INDEX idx_unique ON index_test(id, data);
+SELECT show_index_status('idx_unique');
+  show_index_status   
+----------------------
+ (idx_unique,t,t,t,t)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE id = 500 AND data = 'data 500';
+                        QUERY PLAN                        
+----------------------------------------------------------
+ Index Scan using idx_unique on index_test
+   Index Cond: ((id = 500) AND (data = 'data 500'::text))
+(2 rows)
+
+ALTER INDEX idx_unique DISABLE;
+SELECT show_index_status('idx_unique');
+  show_index_status   
+----------------------
+ (idx_unique,t,t,t,f)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE id = 500 AND data = 'data 500';
+                   QUERY PLAN                   
+------------------------------------------------
+ Index Scan using index_test_pkey on index_test
+   Index Cond: (id = 500)
+   Filter: (data = 'data 500'::text)
+(3 rows)
+
+ALTER INDEX idx_unique ENABLE;
+SELECT show_index_status('idx_unique');
+  show_index_status   
+----------------------
+ (idx_unique,t,t,t,t)
+(1 row)
+
+-- 9. Function-based index
+CREATE INDEX idx_func ON index_test(get_data_length(data));
+SELECT show_index_status('idx_func');
+ show_index_status  
+--------------------
+ (idx_func,t,t,t,t)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE get_data_length(data) = 10;
+               QUERY PLAN                
+-----------------------------------------
+ Bitmap Heap Scan on index_test
+   Recheck Cond: (length(data) = 10)
+   ->  Bitmap Index Scan on idx_func
+         Index Cond: (length(data) = 10)
+(4 rows)
+
+ALTER INDEX idx_func DISABLE;
+SELECT show_index_status('idx_func');
+ show_index_status  
+--------------------
+ (idx_func,t,t,t,f)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE get_data_length(data) = 10;
+          QUERY PLAN           
+-------------------------------
+ Seq Scan on index_test
+   Filter: (length(data) = 10)
+(2 rows)
+
+ALTER INDEX idx_func ENABLE;
+SELECT show_index_status('idx_func');
+ show_index_status  
+--------------------
+ (idx_func,t,t,t,t)
+(1 row)
+
+-- 10. Join index
+CREATE TABLE join_test (id INT PRIMARY KEY, ref_id INT);
+INSERT INTO join_test SELECT g, g % 100 FROM generate_series(1, 1000) g;
+CREATE INDEX idx_join ON join_test(ref_id);
+SELECT show_index_status('idx_join');
+ show_index_status  
+--------------------
+ (idx_join,t,t,t,t)
+(1 row)
+
+EXPLAIN (COSTS OFF)
+SELECT jt.id, it.data
+FROM join_test jt
+JOIN index_test it ON jt.ref_id = it.num
+WHERE jt.id BETWEEN 100 AND 200;
+                          QUERY PLAN                           
+---------------------------------------------------------------
+ Hash Join
+   Hash Cond: (it.num = jt.ref_id)
+   ->  Seq Scan on index_test it
+   ->  Hash
+         ->  Bitmap Heap Scan on join_test jt
+               Recheck Cond: ((id >= 100) AND (id <= 200))
+               ->  Bitmap Index Scan on join_test_pkey
+                     Index Cond: ((id >= 100) AND (id <= 200))
+(8 rows)
+
+-- Disable all indexes to force seq scan
+ALTER INDEX idx_join DISABLE;
+ALTER INDEX join_test_pkey DISABLE;
+SELECT show_index_status('idx_join');
+ show_index_status  
+--------------------
+ (idx_join,t,t,t,f)
+(1 row)
+
+SELECT show_index_status('join_test_pkey');
+    show_index_status     
+--------------------------
+ (join_test_pkey,t,t,t,f)
+(1 row)
+
+EXPLAIN (COSTS OFF)
+SELECT jt.id, it.data
+FROM join_test jt
+JOIN index_test it ON jt.ref_id = it.num
+WHERE jt.id BETWEEN 100 AND 200;
+                     QUERY PLAN                      
+-----------------------------------------------------
+ Hash Join
+   Hash Cond: (it.num = jt.ref_id)
+   ->  Seq Scan on index_test it
+   ->  Hash
+         ->  Seq Scan on join_test jt
+               Filter: ((id >= 100) AND (id <= 200))
+(6 rows)
+
+ALTER INDEX idx_join ENABLE;
+ALTER INDEX join_test_pkey ENABLE;
+SELECT show_index_status('idx_join');
+ show_index_status  
+--------------------
+ (idx_join,t,t,t,t)
+(1 row)
+
+SELECT show_index_status('join_test_pkey');
+    show_index_status     
+--------------------------
+ (join_test_pkey,t,t,t,t)
+(1 row)
+
+-- Test REINDEX CONCURRENTLY
+REINDEX INDEX CONCURRENTLY idx_join;
+SELECT show_index_status('idx_join');
+ show_index_status  
+--------------------
+ (idx_join,t,t,t,t)
+(1 row)
+
+ALTER INDEX idx_join DISABLE;
+SELECT show_index_status('idx_join');
+ show_index_status  
+--------------------
+ (idx_join,t,t,t,f)
+(1 row)
+
+REINDEX INDEX CONCURRENTLY idx_join;
+SELECT show_index_status('idx_join');
+ show_index_status  
+--------------------
+ (idx_join,t,t,t,f)
+(1 row)
+
+SELECT pg_get_indexdef('idx_join'::regclass);
+                                  pg_get_indexdef                                  
+-----------------------------------------------------------------------------------
+ CREATE INDEX idx_join ON schema_to_reindex.join_test USING btree (ref_id) DISABLE
+(1 row)
+
+ALTER INDEX idx_join ENABLE;
+SELECT pg_get_indexdef('idx_join'::regclass);
+                              pg_get_indexdef                              
+---------------------------------------------------------------------------
+ CREATE INDEX idx_join ON schema_to_reindex.join_test USING btree (ref_id)
+(1 row)
+
+-- Clean up
+DROP TABLE index_test;
+DROP TABLE join_test;
+DROP FUNCTION get_data_length;
+DROP FUNCTION show_index_status;
 -- Failure for unauthorized user
 CREATE ROLE regress_reindexuser NOLOGIN;
 SET SESSION ROLE regress_reindexuser;
diff --git a/src/test/regress/sql/create_index.sql b/src/test/regress/sql/create_index.sql
index fe162cc7c3..db547898aa 100644
--- a/src/test/regress/sql/create_index.sql
+++ b/src/test/regress/sql/create_index.sql
@@ -1297,6 +1297,187 @@ END;
 -- concurrently
 REINDEX SCHEMA CONCURRENTLY schema_to_reindex;
 
+-- Test enable/disable functionality for indexes
+
+-- Setup
+CREATE TABLE index_test(
+    id INT PRIMARY KEY,
+    data TEXT,
+    num INT,
+    vector INT[],
+    range INT4RANGE
+);
+
+INSERT INTO index_test
+SELECT
+    g,
+    'data ' || g,
+    g % 100,
+    ARRAY[g, g+1, g+2],
+    int4range(g, g+10)
+FROM generate_series(1, 1000) g;
+
+-- Function for testing
+CREATE FUNCTION get_data_length(text) RETURNS INT AS $$
+    SELECT length($1);
+$$ LANGUAGE SQL IMMUTABLE;
+
+-- Helper function to show index status
+CREATE OR REPLACE FUNCTION show_index_status(index_name text)
+RETURNS TABLE (
+    indexrelid regclass,
+    indisvalid boolean,
+    indisready boolean,
+    indislive boolean,
+    indisenabled boolean
+) AS $$
+BEGIN
+    RETURN QUERY EXECUTE format('
+        SELECT indexrelid::regclass, indisvalid, indisready, indislive, indisenabled
+        FROM pg_index
+        WHERE indexrelid = %L::regclass', index_name);
+END;
+$$ LANGUAGE plpgsql;
+
+-- Create and test each index type
+-- 1. Basic single-column index
+CREATE INDEX idx_single ON index_test(data);
+SELECT show_index_status('idx_single');
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE data = 'data 500';
+ALTER INDEX idx_single DISABLE;
+SELECT show_index_status('idx_single');
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE data = 'data 500';
+ALTER INDEX idx_single ENABLE;
+SELECT show_index_status('idx_single');
+
+-- 2. Multi-column index
+CREATE INDEX idx_multi ON index_test(num, data);
+SELECT show_index_status('idx_multi');
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE num = 50 AND data > 'data 500';
+ALTER INDEX idx_multi DISABLE;
+SELECT show_index_status('idx_multi');
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE num = 50 AND data > 'data 500';
+ALTER INDEX idx_multi ENABLE;
+SELECT show_index_status('idx_multi');
+
+-- 3. Partial index
+CREATE INDEX idx_partial ON index_test(num) WHERE num < 50;
+SELECT show_index_status('idx_partial');
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE num = 25;
+ALTER INDEX idx_partial DISABLE;
+SELECT show_index_status('idx_partial');
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE num = 25;
+ALTER INDEX idx_partial ENABLE;
+SELECT show_index_status('idx_partial');
+
+-- 4. Expression index
+CREATE INDEX idx_expression ON index_test((lower(data)));
+SELECT show_index_status('idx_expression');
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE lower(data) = 'data 500';
+ALTER INDEX idx_expression DISABLE;
+SELECT show_index_status('idx_expression');
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE lower(data) = 'data 500';
+ALTER INDEX idx_expression ENABLE;
+SELECT show_index_status('idx_expression');
+
+-- 5. GIN index
+CREATE INDEX idx_gin ON index_test USING gin(vector);
+SELECT show_index_status('idx_gin');
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE vector @> ARRAY[500];
+ALTER INDEX idx_gin DISABLE;
+SELECT show_index_status('idx_gin');
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE vector @> ARRAY[500];
+ALTER INDEX idx_gin ENABLE;
+SELECT show_index_status('idx_gin');
+
+-- 6. GiST index
+CREATE INDEX idx_gist ON index_test USING gist(range);
+SELECT show_index_status('idx_gist');
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE range && int4range(100, 110);
+ALTER INDEX idx_gist DISABLE;
+SELECT show_index_status('idx_gist');
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE range && int4range(100, 110);
+ALTER INDEX idx_gist ENABLE;
+SELECT show_index_status('idx_gist');
+
+-- 7. Covering index
+CREATE INDEX idx_covering ON index_test(num) INCLUDE (data);
+SELECT show_index_status('idx_covering');
+EXPLAIN (COSTS OFF) SELECT num, data FROM index_test WHERE num = 50;
+ALTER INDEX idx_covering DISABLE;
+SELECT show_index_status('idx_covering');
+EXPLAIN (COSTS OFF) SELECT num, data FROM index_test WHERE num = 50;
+ALTER INDEX idx_covering ENABLE;
+SELECT show_index_status('idx_covering');
+
+-- 8. Unique index
+CREATE UNIQUE INDEX idx_unique ON index_test(id, data);
+SELECT show_index_status('idx_unique');
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE id = 500 AND data = 'data 500';
+ALTER INDEX idx_unique DISABLE;
+SELECT show_index_status('idx_unique');
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE id = 500 AND data = 'data 500';
+ALTER INDEX idx_unique ENABLE;
+SELECT show_index_status('idx_unique');
+
+-- 9. Function-based index
+CREATE INDEX idx_func ON index_test(get_data_length(data));
+SELECT show_index_status('idx_func');
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE get_data_length(data) = 10;
+ALTER INDEX idx_func DISABLE;
+SELECT show_index_status('idx_func');
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE get_data_length(data) = 10;
+ALTER INDEX idx_func ENABLE;
+SELECT show_index_status('idx_func');
+
+-- 10. Join index
+CREATE TABLE join_test (id INT PRIMARY KEY, ref_id INT);
+INSERT INTO join_test SELECT g, g % 100 FROM generate_series(1, 1000) g;
+CREATE INDEX idx_join ON join_test(ref_id);
+SELECT show_index_status('idx_join');
+
+EXPLAIN (COSTS OFF)
+SELECT jt.id, it.data
+FROM join_test jt
+JOIN index_test it ON jt.ref_id = it.num
+WHERE jt.id BETWEEN 100 AND 200;
+
+-- Disable all indexes to force seq scan
+ALTER INDEX idx_join DISABLE;
+ALTER INDEX join_test_pkey DISABLE;
+SELECT show_index_status('idx_join');
+SELECT show_index_status('join_test_pkey');
+
+EXPLAIN (COSTS OFF)
+SELECT jt.id, it.data
+FROM join_test jt
+JOIN index_test it ON jt.ref_id = it.num
+WHERE jt.id BETWEEN 100 AND 200;
+
+ALTER INDEX idx_join ENABLE;
+ALTER INDEX join_test_pkey ENABLE;
+SELECT show_index_status('idx_join');
+SELECT show_index_status('join_test_pkey');
+
+-- Test REINDEX CONCURRENTLY
+REINDEX INDEX CONCURRENTLY idx_join;
+SELECT show_index_status('idx_join');
+
+ALTER INDEX idx_join DISABLE;
+SELECT show_index_status('idx_join');
+REINDEX INDEX CONCURRENTLY idx_join;
+SELECT show_index_status('idx_join');
+
+SELECT pg_get_indexdef('idx_join'::regclass);
+ALTER INDEX idx_join ENABLE;
+SELECT pg_get_indexdef('idx_join'::regclass);
+
+-- Clean up
+DROP TABLE index_test;
+DROP TABLE join_test;
+DROP FUNCTION get_data_length;
+DROP FUNCTION show_index_status;
+
 -- Failure for unauthorized user
 CREATE ROLE regress_reindexuser NOLOGIN;
 SET SESSION ROLE regress_reindexuser;
-- 
2.37.1 (Apple Git-137.1)

#43Rafia Sabih
rafia.pghackers@gmail.com
In reply to: Shayon Mukherjee (#42)
Re: Proposal to Enable/Disable Index using ALTER INDEX (with patch)

Interesting idea.
This patch needs a rebase.

On Thu, 17 Oct 2024 at 15:59, Shayon Mukherjee <shayonj@gmail.com> wrote:

On Oct 16, 2024, at 6:01 PM, Shayon Mukherjee <shayonj@gmail.com> wrote:

I'll take some time to think this through and familiarize myself with the
new systable_inplace_update_begin. In the meantime, aside from the in-place
updates on pg_index, I would love to learn any first impressions or
feedback on the patch folks may have.

My take away from whether or not an in-place update is needed on pg_index
[1]

- It’s unclear to me why it’s needed.
- I understand the xmin would get incremented when
using CatalogTupleUpdate to update indisenabled.
- However, I haven’t been able to replicate any odd behavior locally or
CI.
- FWIW - REINDEX CONCURRENTLY (via index_swap), index_constraint_create
and few other places perform CatalogTupleUpdate to update the relevant
attributes as well.

Based on the above summary and after my testing I would like to propose a
v3 of the patch. The only difference between this and v1 [2] is that the
update of pg_index row happens via CatalogTupleUpdate.

[1]
/messages/by-id/20180618215635.m5vrnxdxhxytvmcm@alap3.anarazel.de
[2]
/messages/by-id/EF2313B8-A017-4869-9B7F-A24EDD8795DE@gmail.com

Thank you for bearing with me on this :D
Shayon

--
Regards,
Rafia Sabih
CYBERTEC PostgreSQL International GmbH

#44Robert Haas
robertmhaas@gmail.com
In reply to: Shayon Mukherjee (#42)
Re: Proposal to Enable/Disable Index using ALTER INDEX (with patch)

On Thu, Oct 17, 2024 at 9:59 AM Shayon Mukherjee <shayonj@gmail.com> wrote:

My take away from whether or not an in-place update is needed on pg_index [1]

- It’s unclear to me why it’s needed.
- I understand the xmin would get incremented when using CatalogTupleUpdate to update indisenabled.
- However, I haven’t been able to replicate any odd behavior locally or CI.
- FWIW - REINDEX CONCURRENTLY (via index_swap), index_constraint_create and few other places perform CatalogTupleUpdate to update the relevant attributes as well.

Based on the above summary and after my testing I would like to propose a v3 of the patch. The only difference between this and v1 [2] is that the update of pg_index row happens via CatalogTupleUpdate.

[1] /messages/by-id/20180618215635.m5vrnxdxhxytvmcm@alap3.anarazel.de
[2] /messages/by-id/EF2313B8-A017-4869-9B7F-A24EDD8795DE@gmail.com

In-place updates are generally bad news, so I think this patch
shouldn't use them. However, someone will need to investigate whether
that breaks the indcheckxmin thing that Andres mentions in your [1],
and if it does, figure out what to do about it. Creating a test case
to show the breakage would probably be a good first step, to frame the
discussion.

--
Robert Haas
EDB: http://www.enterprisedb.com

#45Shayon Mukherjee
shayonj@gmail.com
In reply to: Robert Haas (#44)
Re: Proposal to Enable/Disable Index using ALTER INDEX (with patch)

On Nov 5, 2024, at 10:55 AM, Robert Haas <robertmhaas@gmail.com> wrote:

On Thu, Oct 17, 2024 at 9:59 AM Shayon Mukherjee <shayonj@gmail.com> wrote:

My take away from whether or not an in-place update is needed on pg_index [1]

- It’s unclear to me why it’s needed.
- I understand the xmin would get incremented when using CatalogTupleUpdate to update indisenabled.
- However, I haven’t been able to replicate any odd behavior locally or CI.
- FWIW - REINDEX CONCURRENTLY (via index_swap), index_constraint_create and few other places perform CatalogTupleUpdate to update the relevant attributes as well.

Based on the above summary and after my testing I would like to propose a v3 of the patch. The only difference between this and v1 [2] is that the update of pg_index row happens via CatalogTupleUpdate.

[1] /messages/by-id/20180618215635.m5vrnxdxhxytvmcm@alap3.anarazel.de
[2] /messages/by-id/EF2313B8-A017-4869-9B7F-A24EDD8795DE@gmail.com

In-place updates are generally bad news, so I think this patch
shouldn't use them. However, someone will need to investigate whether
that breaks the indcheckxmin thing that Andres mentions in your [1],
and if it does, figure out what to do about it. Creating a test case
to show the breakage would probably be a good first step, to frame the
discussion.

Hello,

Thank you for the guidance and tips. I was wondering if updating in-place is preferable or not, since my first instinct was to avoid it. I did not notice any breakage last time, unless I was looking in the wrong place (possibly?). I did notice the min update when a not-in-place update was performed, but I didn't notice any issues (as mentioned in [1]/messages/by-id/20180618215635.m5vrnxdxhxytvmcm@alap3.anarazel.de) from it, via logs, index usage, or other common operations. Let me write up some more test cases to check if there is a risk of indexcheckxmin running out or other issues, and I'll get back here.

Thank you
Shayon

[1]: /messages/by-id/20180618215635.m5vrnxdxhxytvmcm@alap3.anarazel.de

Show quoted text

--
Robert Haas
EDB: http://www.enterprisedb.com

#46David Rowley
dgrowleyml@gmail.com
In reply to: Shayon Mukherjee (#45)
Re: Proposal to Enable/Disable Index using ALTER INDEX (with patch)

On Tue, 26 Nov 2024 at 11:34, Shayon Mukherjee <shayonj@gmail.com> wrote:

Thank you for the guidance and tips. I was wondering if updating in-place is preferable or not, since my first instinct was to avoid it. I did not notice any breakage last time, unless I was looking in the wrong place (possibly?). I did notice the min update when a not-in-place update was performed, but I didn't notice any issues (as mentioned in [1]) from it, via logs, index usage, or other common operations. Let me write up some more test cases to check if there is a risk of indexcheckxmin running out or other issues, and I'll get back here.

Another safer option could be to disallow the enable/disable ALTER
TABLE if indcheckxmin is true. We do have and use
ERRCODE_OBJECT_NOT_IN_PREREQUISITE_STATE for these sorts of issues.
There are other existing failure modes relating to indexes that can
depend on what another session has done, e.g. MarkInheritDetached()
can fail if another session detached an index concurrently. I could
respect an argument that this one might be worse than that as its
timing dependent rather than dependent on what another session has
done.

David

#47Shayon Mukherjee
shayonj@gmail.com
In reply to: David Rowley (#46)
1 attachment(s)
Re: Proposal to Enable/Disable Index using ALTER INDEX (with patch)

On Mon, Nov 25, 2024 at 6:19 PM David Rowley <dgrowleyml@gmail.com> wrote:

Another safer option could be to disallow the enable/disable ALTER
TABLE if indcheckxmin is true. We do have and use
ERRCODE_OBJECT_NOT_IN_PREREQUISITE_STATE for these sorts of issues.
There are other existing failure modes relating to indexes that can
depend on what another session has done, e.g. MarkInheritDetached()
can fail if another session detached an index concurrently. I could
respect an argument that this one might be worse than that as its
timing dependent rather than dependent on what another session has
done.

Thank you for that feedback David. It's very useful.

I have attached a v4 patch that now raises an error if indcheckxmin is true
before attempting to enable/disable an index, and asks the caller to wait
until indcheckxmin is balanced again via log message.

I couldn't come up with any reliable (non-flaky) way of getting
indcheckxmin to report true in regression specs for extra coverage. So, I
ended up "simulating" it by directly updating the relevant row for an index
and marking indcheckxmin as true in specs and accordingly asserting. The
specs now cover all the previous cases and also the new case where the
error would be raised if the caller attempts to enable/disable an index
while indcheckxmin is true.

The patch is also rebased against the latest master and passing in CI.
Would love to receive any further feedback on it.

Thank you everyone!
Shayon

Attachments:

v4-0001-Introduce-the-ability-to-enable-disable-indexes-u.patchapplication/octet-stream; name=v4-0001-Introduce-the-ability-to-enable-disable-indexes-u.patchDownload
From e64b19d92e95dedc4c351d45a4c418a078cae696 Mon Sep 17 00:00:00 2001
From: Shayon Mukherjee <shayonj@gmail.com>
Date: Thu, 17 Oct 2024 10:04:13 -0400
Subject: [PATCH v4] Introduce the ability to enable/disable indexes using
 ALTER INDEX

This patch introduces the ability to enable or disable indexes using ALTER INDEX
and CREATE INDEX commands.

Original motivation for the problem and proposal for a patch
can be found at [1].

This patch passes all the existing specs and the newly added regression tests. The patch
is ready for review and test. It compiles, so the can patch can be applied for testing as well.

Implementation details:

- New Grammar:
  * ALTER INDEX ... ENABLE/DISABLE
  * CREATE INDEX ... DISABLE

- Default state is enabled. Indexes are only disabled when explicitly
  instructed via CREATE INDEX ... DISABLE or ALTER INDEX ... DISABLE.

- Primary Key and Unique constraint indexes are always enabled as well. The
  ENABLE/DISABLE grammar is not supported for these types of indexes. They can
  be later disabled via ALTER INDEX ... ENABLE/DISABLE.

- ALTER INDEX ... ENABLE/DISABLE performs update on the relevant row in pg_index
  catalog

- pg_get_indexdef() support the new functionality and grammar. This change is
  reflected in \d output for tables and pg_dump. We show the DISABLE syntax accordingly.

- Updated create_index.sql regression test to cover the new grammar and verify
  that disabled indexes are not used in queries. The test CATALOG_VERSION_NO

  - Basic single-column and multi-column indexes
  - Partial indexes
  - Expression indexes
  - Join indexes
  - GIN and GiST indexes
  - Covering indexes
  - Range indexes
  - Unique indexes and constraints

- Adds a new enabled attribute to the IndexOptInfo structure.

- Modifies get_relation_info in plancat.c to skip disabled indexes entirely, thus reducing the number of places we need to check if an index is disabled or not. Inspired by the conversations start at [2].
  - I chose to modify the logic within get_relation_info as compared to, say, reducing the cost to make the planner not consider an index during planning, mostly to keep the number of changes being introduced to a minimum and also the logic itself being self-contained and easier to under perhaps (?).

- No changes are made to stop the index from getting rebuilt. This way we ensure no
  data miss or corruption when index is re-nabled.

- TOAST indexes are supported and enabled by default as well.

- REINDEX CONCURRENTLY is supported as well and existing state of pg_index.indisenabled
  is carried over accordingly.

- See the changes in create_index.sql to get an idea of the grammar and sql statements.

- See the changes in create_index.out to get an idea of the catalogue states and EXPLAIN
  output to see when an index is getting used or isn't (when disabled).

- Incorporated DavidR's feedback from [3] around documentation and also you will see that by skip disabled indexes entirely from get_relation_info in plancat.c (as mentioned above), we address the other mentioned issues as well.

- Lastly, protects against the case where indcheckxmin is true by raising ERRCODE_OBJECT_NOT_IN_PREREQUISITE_STATE.

Looking forward to any and all feedback on this patch, including but not limited to code quality, tests, fundamental logic.

[1] https://www.postgresql.org/message-id/CANqtF-oXKe0M%3D0QOih6H%2BsZRjE2BWAbkW_1%2B9nMEAMLxUJg5jA%40mail.gmail.com
[2] https://www.postgresql.org/message-id/3465209.1727202064%40sss.pgh.pa.us
[3] https://www.postgresql.org/message-id/CAApHDvpUNu%3DiVcdJ74sypvgeaCF%2Btfpyb8VRhZaF7DTd1xVr7g%40mail.gmail.com
---
 doc/src/sgml/catalogs.sgml                 |  11 +
 doc/src/sgml/ref/alter_index.sgml          |  43 ++
 doc/src/sgml/ref/create_index.sgml         |  29 ++
 src/backend/bootstrap/bootparse.y          |   2 +
 src/backend/catalog/index.c                |  31 +-
 src/backend/catalog/toasting.c             |   2 +-
 src/backend/commands/indexcmds.c           |   4 +
 src/backend/commands/tablecmds.c           |  67 ++-
 src/backend/optimizer/util/plancat.c       |  13 +
 src/backend/parser/gram.y                  |  48 +-
 src/backend/parser/parse_utilcmd.c         |   3 +
 src/backend/utils/adt/ruleutils.c          |   4 +
 src/backend/utils/cache/relcache.c         |   1 +
 src/include/catalog/index.h                |   2 +-
 src/include/catalog/pg_index.h             |   1 +
 src/include/nodes/parsenodes.h             |   3 +
 src/include/nodes/pathnodes.h              |   2 +
 src/test/regress/expected/create_index.out | 505 +++++++++++++++++++++
 src/test/regress/sql/create_index.sql      | 192 ++++++++
 19 files changed, 953 insertions(+), 10 deletions(-)

diff --git a/doc/src/sgml/catalogs.sgml b/doc/src/sgml/catalogs.sgml
index bf3cee08a93..87c45708816 100644
--- a/doc/src/sgml/catalogs.sgml
+++ b/doc/src/sgml/catalogs.sgml
@@ -4596,6 +4596,17 @@ SCRAM-SHA-256$<replaceable>&lt;iteration count&gt;</replaceable>:<replaceable>&l
        partial index.
       </para></entry>
      </row>
+
+     <row>
+      <entry role="catalog_table_entry"><para role="column_definition">
+       <structfield>indisenabled</structfield> <type>bool</type>
+      </para>
+      <para>
+       If true, the index is currently enabled and should be used for queries.
+       If false, the index is disabled and should not be used for queries,
+       but is still maintained when the table is modified. Default is true.
+      </para></entry>
+     </row>
     </tbody>
    </tgroup>
   </table>
diff --git a/doc/src/sgml/ref/alter_index.sgml b/doc/src/sgml/ref/alter_index.sgml
index 1d42d05d858..04b3b0b9bfe 100644
--- a/doc/src/sgml/ref/alter_index.sgml
+++ b/doc/src/sgml/ref/alter_index.sgml
@@ -31,6 +31,8 @@ ALTER INDEX [ IF EXISTS ] <replaceable class="parameter">name</replaceable> ALTE
     SET STATISTICS <replaceable class="parameter">integer</replaceable>
 ALTER INDEX ALL IN TABLESPACE <replaceable class="parameter">name</replaceable> [ OWNED BY <replaceable class="parameter">role_name</replaceable> [, ... ] ]
     SET TABLESPACE <replaceable class="parameter">new_tablespace</replaceable> [ NOWAIT ]
+ALTER INDEX [ IF EXISTS ] <replaceable class="parameter">name</replaceable> ENABLE
+ALTER INDEX [ IF EXISTS ] <replaceable class="parameter">name</replaceable> DISABLE
 </synopsis>
  </refsynopsisdiv>
 
@@ -159,6 +161,33 @@ ALTER INDEX ALL IN TABLESPACE <replaceable class="parameter">name</replaceable>
     </listitem>
    </varlistentry>
 
+   <varlistentry>
+    <term><literal>ENABLE</literal></term>
+    <listitem>
+     <para>
+      Enable the specified index. The index will be used by the query planner
+      for query optimization. This is the default state for newly created indexes.
+     </para>
+    </listitem>
+   </varlistentry>
+
+   <varlistentry>
+    <term><literal>DISABLE</literal></term>
+    <listitem>
+     <para>
+      Disable the specified index. A disabled index is not used by the query planner
+      for query optimization, but it is still maintained when the underlying table
+      data changes. This can be useful for testing query performance with and without
+      specific indexes, temporarily reducing the overhead of index maintenance
+      during bulk data loading operations, or verifying an index is not being used
+      before dropping it. If performance degrades after disabling an index, it can be
+      easily re-enabled. Before disabling, it's recommended to check
+      <structname>pg_stat_user_indexes</structname>.<structfield>idx_scan</structfield>
+      to identify potentially unused indexes.
+     </para>
+    </listitem>
+   </varlistentry>
+
   </variablelist>
   </para>
 
@@ -301,6 +330,20 @@ CREATE INDEX coord_idx ON measured (x, y, (z + t));
 ALTER INDEX coord_idx ALTER COLUMN 3 SET STATISTICS 1000;
 </programlisting></para>
 
+  <para>
+   To enable an index:
+<programlisting>
+ALTER INDEX idx_name ENABLE;
+</programlisting>
+  </para>
+
+  <para>
+   To disable an index:
+<programlisting>
+ALTER INDEX idx_name DISABLE;
+</programlisting>
+  </para>
+
  </refsect1>
 
  <refsect1>
diff --git a/doc/src/sgml/ref/create_index.sgml b/doc/src/sgml/ref/create_index.sgml
index 621bc0e253c..f1eebfa250c 100644
--- a/doc/src/sgml/ref/create_index.sgml
+++ b/doc/src/sgml/ref/create_index.sgml
@@ -28,6 +28,7 @@ CREATE [ UNIQUE ] INDEX [ CONCURRENTLY ] [ [ IF NOT EXISTS ] <replaceable class=
     [ WITH ( <replaceable class="parameter">storage_parameter</replaceable> [= <replaceable class="parameter">value</replaceable>] [, ... ] ) ]
     [ TABLESPACE <replaceable class="parameter">tablespace_name</replaceable> ]
     [ WHERE <replaceable class="parameter">predicate</replaceable> ]
+    [ DISABLE ]
 </synopsis>
  </refsynopsisdiv>
 
@@ -380,6 +381,19 @@ CREATE [ UNIQUE ] INDEX [ CONCURRENTLY ] [ [ IF NOT EXISTS ] <replaceable class=
       </listitem>
      </varlistentry>
 
+    <varlistentry>
+      <term><literal>DISABLE</literal></term>
+      <listitem>
+       <para>
+        Creates the index in a disabled state (default enabled). A disabled index is not used by the
+        query planner for query optimization, but it is still maintained when the
+        underlying table data changes. This can be useful when you want to create
+        an index without immediately impacting query performance, allowing you to
+        enable it later at a more convenient time. The index can be enabled later
+        using <command>ALTER INDEX ... ENABLE</command>.
+       </para>
+      </listitem>
+     </varlistentry>
     </variablelist>
 
   <refsect2 id="sql-createindex-storage-parameters" xreflabel="Index Storage Parameters">
@@ -701,6 +715,14 @@ Indexes:
     partitioned index is a metadata only operation.
    </para>
 
+  <para>
+   When creating an index with the <literal>DISABLE</literal> option, the index
+   will be created but not used for query planning. This can be useful for
+   preparing an index in advance of its use, or for testing purposes. The index
+   will still be maintained as the table is modified, so it can be enabled
+   later without needing to be rebuilt. By default all new indexes are enabled.
+  </para>
+
   </refsect2>
  </refsect1>
 
@@ -980,6 +1002,13 @@ SELECT * FROM points
 CREATE INDEX CONCURRENTLY sales_quantity_index ON sales_table (quantity);
 </programlisting></para>
 
+  <para>
+   To create an index on the table <literal>test_table</literal> with the default
+   name, but have it initially disabled:
+<programlisting>
+CREATE INDEX ON test_table (col1) DISABLE;
+</programlisting>
+  </para>
  </refsect1>
 
  <refsect1>
diff --git a/src/backend/bootstrap/bootparse.y b/src/backend/bootstrap/bootparse.y
index 73a7592fb71..6023d584904 100644
--- a/src/backend/bootstrap/bootparse.y
+++ b/src/backend/bootstrap/bootparse.y
@@ -302,6 +302,7 @@ Boot_DeclareIndexStmt:
 					stmt->concurrent = false;
 					stmt->if_not_exists = false;
 					stmt->reset_default_tblspc = false;
+					stmt->isenabled = true;
 
 					/* locks and races need not concern us in bootstrap mode */
 					relationId = RangeVarGetRelid(stmt->relation, NoLock,
@@ -355,6 +356,7 @@ Boot_DeclareUniqueIndexStmt:
 					stmt->concurrent = false;
 					stmt->if_not_exists = false;
 					stmt->reset_default_tblspc = false;
+					stmt->isenabled = true;
 
 					/* locks and races need not concern us in bootstrap mode */
 					relationId = RangeVarGetRelid(stmt->relation, NoLock,
diff --git a/src/backend/catalog/index.c b/src/backend/catalog/index.c
index 1c3a9e06d37..9c529b1979f 100644
--- a/src/backend/catalog/index.c
+++ b/src/backend/catalog/index.c
@@ -118,7 +118,8 @@ static void UpdateIndexRelation(Oid indexoid, Oid heapoid,
 								bool isexclusion,
 								bool immediate,
 								bool isvalid,
-								bool isready);
+								bool isready,
+								bool isenabled);
 static void index_update_stats(Relation rel,
 							   bool hasindex,
 							   double reltuples);
@@ -569,7 +570,8 @@ UpdateIndexRelation(Oid indexoid,
 					bool isexclusion,
 					bool immediate,
 					bool isvalid,
-					bool isready)
+					bool isready,
+					bool isenabled)
 {
 	int2vector *indkey;
 	oidvector  *indcollation;
@@ -647,6 +649,7 @@ UpdateIndexRelation(Oid indexoid,
 	values[Anum_pg_index_indisready - 1] = BoolGetDatum(isready);
 	values[Anum_pg_index_indislive - 1] = BoolGetDatum(true);
 	values[Anum_pg_index_indisreplident - 1] = BoolGetDatum(false);
+	values[Anum_pg_index_indisenabled - 1] = BoolGetDatum(isenabled);
 	values[Anum_pg_index_indkey - 1] = PointerGetDatum(indkey);
 	values[Anum_pg_index_indcollation - 1] = PointerGetDatum(indcollation);
 	values[Anum_pg_index_indclass - 1] = PointerGetDatum(indclass);
@@ -712,6 +715,8 @@ UpdateIndexRelation(Oid indexoid,
  *			already exists.
  *		INDEX_CREATE_PARTITIONED:
  *			create a partitioned index (table must be partitioned)
+ *		INDEX_CREATE_DISABLED:
+*				create the index as disabled if instructed, defaults to being enabled.
  * constr_flags: flags passed to index_constraint_create
  *		(only if INDEX_CREATE_ADD_CONSTRAINT is set)
  * allow_system_table_mods: allow table to be a system catalog
@@ -757,6 +762,7 @@ index_create(Relation heapRelation,
 	bool		invalid = (flags & INDEX_CREATE_INVALID) != 0;
 	bool		concurrent = (flags & INDEX_CREATE_CONCURRENT) != 0;
 	bool		partitioned = (flags & INDEX_CREATE_PARTITIONED) != 0;
+	bool 		isenabled  = (flags & INDEX_CREATE_ENABLED) != 0;
 	char		relkind;
 	TransactionId relfrozenxid;
 	MultiXactId relminmxid;
@@ -1040,13 +1046,15 @@ index_create(Relation heapRelation,
 	 *	  (Or, could define a rule to maintain the predicate) --Nels, Feb '92
 	 * ----------------
 	 */
+
 	UpdateIndexRelation(indexRelationId, heapRelationId, parentIndexRelid,
 						indexInfo,
 						collationIds, opclassIds, coloptions,
 						isprimary, is_exclusion,
 						(constr_flags & INDEX_CONSTR_CREATE_DEFERRABLE) == 0,
 						!concurrent && !invalid,
-						!concurrent);
+						!concurrent,
+						isenabled);
 
 	/*
 	 * Register relcache invalidation on the indexes' heap relation, to
@@ -1315,6 +1323,8 @@ index_concurrently_create_copy(Relation heapRelation, Oid oldIndexId,
 	List	   *indexColNames = NIL;
 	List	   *indexExprs = NIL;
 	List	   *indexPreds = NIL;
+	Form_pg_index indexForm;
+	bits16 	 createFlags;
 
 	indexRelation = index_open(oldIndexId, RowExclusiveLock);
 
@@ -1342,6 +1352,9 @@ index_concurrently_create_copy(Relation heapRelation, Oid oldIndexId,
 											Anum_pg_index_indoption);
 	indcoloptions = (int2vector *) DatumGetPointer(colOptionDatum);
 
+	/* Get the enabled state of the original index */
+	indexForm = (Form_pg_index) GETSTRUCT(indexTuple);
+
 	/* Fetch reloptions of index if any */
 	classTuple = SearchSysCache1(RELOID, ObjectIdGetDatum(oldIndexId));
 	if (!HeapTupleIsValid(classTuple))
@@ -1433,6 +1446,16 @@ index_concurrently_create_copy(Relation heapRelation, Oid oldIndexId,
 		stattargets[i].isnull = isnull;
 	}
 
+	/*
+	* Determine the create flags for the new index.
+	* We always use SKIP_BUILD and CONCURRENT for concurrent reindexing.
+	* If the original index was enabled, we also set the ENABLED flag
+	* to maintain the same state in the new index.
+	*/
+	createFlags = INDEX_CREATE_SKIP_BUILD | INDEX_CREATE_CONCURRENT;
+	if (indexForm->indisenabled)
+			createFlags |= INDEX_CREATE_ENABLED;
+
 	/*
 	 * Now create the new index.
 	 *
@@ -1456,7 +1479,7 @@ index_concurrently_create_copy(Relation heapRelation, Oid oldIndexId,
 							  indcoloptions->values,
 							  stattargets,
 							  reloptionsDatum,
-							  INDEX_CREATE_SKIP_BUILD | INDEX_CREATE_CONCURRENT,
+							  createFlags,
 							  0,
 							  true, /* allow table to be a system catalog? */
 							  false,	/* is_internal? */
diff --git a/src/backend/catalog/toasting.c b/src/backend/catalog/toasting.c
index ad3082c62ac..dead993a742 100644
--- a/src/backend/catalog/toasting.c
+++ b/src/backend/catalog/toasting.c
@@ -325,7 +325,7 @@ create_toast_table(Relation rel, Oid toastOid, Oid toastIndexOid,
 				 BTREE_AM_OID,
 				 rel->rd_rel->reltablespace,
 				 collationIds, opclassIds, NULL, coloptions, NULL, (Datum) 0,
-				 INDEX_CREATE_IS_PRIMARY, 0, true, true, NULL);
+				 INDEX_CREATE_IS_PRIMARY | INDEX_CREATE_ENABLED, 0, true, true, NULL);
 
 	table_close(toast_rel, NoLock);
 
diff --git a/src/backend/commands/indexcmds.c b/src/backend/commands/indexcmds.c
index 4049ce1a10f..b456069f942 100644
--- a/src/backend/commands/indexcmds.c
+++ b/src/backend/commands/indexcmds.c
@@ -1198,6 +1198,10 @@ DefineIndex(Oid tableId,
 		flags |= INDEX_CREATE_PARTITIONED;
 	if (stmt->primary)
 		flags |= INDEX_CREATE_IS_PRIMARY;
+   if (stmt->isenabled)
+		flags |= INDEX_CREATE_ENABLED;
+   else
+		flags &= ~INDEX_CREATE_ENABLED;
 
 	/*
 	 * If the table is partitioned, and recursion was declined but partitions
diff --git a/src/backend/commands/tablecmds.c b/src/backend/commands/tablecmds.c
index 6ccae4cb4a8..45ade205d1f 100644
--- a/src/backend/commands/tablecmds.c
+++ b/src/backend/commands/tablecmds.c
@@ -688,7 +688,7 @@ static List *GetParentedForeignKeyRefs(Relation partition);
 static void ATDetachCheckNoForeignKeyRefs(Relation partition);
 static char GetAttributeCompression(Oid atttypid, const char *compression);
 static char GetAttributeStorage(Oid atttypid, const char *storagemode);
-
+static void ATExecEnableDisableIndex(Relation rel, bool enable);
 
 /* ----------------------------------------------------------------
  *		DefineRelation
@@ -4628,6 +4628,8 @@ AlterTableGetLockLevel(List *cmds)
 			case AT_SetExpression:
 			case AT_DropExpression:
 			case AT_SetCompression:
+			case AT_EnableIndex:
+			case AT_DisableIndex:
 				cmd_lockmode = AccessExclusiveLock;
 				break;
 
@@ -5190,6 +5192,12 @@ ATPrepCmd(List **wqueue, Relation rel, AlterTableCmd *cmd,
 			/* No command-specific prep needed */
 			pass = AT_PASS_MISC;
 			break;
+		case AT_EnableIndex:
+		case AT_DisableIndex:
+			ATSimplePermissions(cmd->subtype, rel, ATT_INDEX | ATT_PARTITIONED_INDEX);
+			/* No command-specific prep needed */
+			pass = AT_PASS_MISC;
+			break;
 		default:				/* oops */
 			elog(ERROR, "unrecognized alter table type: %d",
 				 (int) cmd->subtype);
@@ -5584,6 +5592,12 @@ ATExecCmd(List **wqueue, AlteredTableInfo *tab,
 		case AT_DetachPartitionFinalize:
 			address = ATExecDetachPartitionFinalize(rel, ((PartitionCmd *) cmd->def)->name);
 			break;
+		case AT_EnableIndex:
+				ATExecEnableDisableIndex(rel, true);
+				break;
+		case AT_DisableIndex:
+				ATExecEnableDisableIndex(rel, false);
+				break;
 		default:				/* oops */
 			elog(ERROR, "unrecognized alter table type: %d",
 				 (int) cmd->subtype);
@@ -6473,6 +6487,8 @@ alter_table_type_to_string(AlterTableType cmdtype)
 			return "DROP COLUMN";
 		case AT_AddIndex:
 		case AT_ReAddIndex:
+		case AT_EnableIndex:
+		case AT_DisableIndex:
 			return NULL;		/* not real grammar */
 		case AT_AddConstraint:
 		case AT_ReAddConstraint:
@@ -20808,3 +20824,52 @@ GetAttributeStorage(Oid atttypid, const char *storagemode)
 
 	return cstorage;
 }
+
+/*
+ * ATExecEnableDisableIndex
+ * Performs a catalog update to enable or disable an index in pg_index.
+ */
+static void
+ATExecEnableDisableIndex(Relation rel, bool enable)
+{
+	Oid         indexOid = RelationGetRelid(rel);
+	Relation    pg_index;
+	HeapTuple   indexTuple;
+	Form_pg_index indexForm;
+	bool        updated = false;
+
+	pg_index = table_open(IndexRelationId, RowExclusiveLock);
+
+	indexTuple = SearchSysCacheCopy1(INDEXRELID, ObjectIdGetDatum(indexOid));
+	if (!HeapTupleIsValid(indexTuple))
+		elog(ERROR, "could not find tuple for index %u", indexOid);
+
+	indexForm = (Form_pg_index) GETSTRUCT(indexTuple);
+	if (indexForm->indcheckxmin)
+	{
+		heap_freetuple(indexTuple);
+		table_close(pg_index, RowExclusiveLock);
+		ereport(ERROR,
+				(errcode(ERRCODE_OBJECT_NOT_IN_PREREQUISITE_STATE),
+				errmsg("cannot enable/disable index while indcheckxmin is true"),
+				errhint("Wait for all transactions that might see inconsistent HOT chains to complete")));
+	}
+
+	if (indexForm->indisenabled != enable)
+	{
+		indexForm->indisenabled = enable;
+
+		CatalogTupleUpdate(pg_index, &indexTuple->t_self, indexTuple);
+		updated = true;
+	}
+
+	heap_freetuple(indexTuple);
+	table_close(pg_index, RowExclusiveLock);
+
+	if (updated)
+	{
+		CacheInvalidateRelcache(rel);
+		InvokeObjectPostAlterHook(IndexRelationId, indexOid, 0);
+		CommandCounterIncrement();
+	}
+}
diff --git a/src/backend/optimizer/util/plancat.c b/src/backend/optimizer/util/plancat.c
index 37b0ca2e439..78c481c61f9 100644
--- a/src/backend/optimizer/util/plancat.c
+++ b/src/backend/optimizer/util/plancat.c
@@ -295,6 +295,19 @@ get_relation_info(PlannerInfo *root, Oid relationObjectId, bool inhparent,
 			info->opcintype = (Oid *) palloc(sizeof(Oid) * nkeycolumns);
 			info->canreturn = (bool *) palloc(sizeof(bool) * ncolumns);
 
+			/*
+			 * Skip disabled indexes altogether, as they should not be considered
+			 * for query planning. This builds the data structure for the planner's
+			 * use and we make it part of IndexOptInfo since the index is already open.
+			 * We also close the relation before continuing to the next index.
+			 */
+			info->enabled = index->indisenabled;
+			if (!info->enabled)
+			{
+				index_close(indexRelation, NoLock);
+				continue;
+			}
+
 			for (i = 0; i < ncolumns; i++)
 			{
 				info->indexkeys[i] = index->indkey.values[i];
diff --git a/src/backend/parser/gram.y b/src/backend/parser/gram.y
index 67eb96396af..e34ade79056 100644
--- a/src/backend/parser/gram.y
+++ b/src/backend/parser/gram.y
@@ -320,7 +320,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 %type <ival>	add_drop opt_asc_desc opt_nulls_order
 
 %type <node>	alter_table_cmd alter_type_cmd opt_collate_clause
-	   replica_identity partition_cmd index_partition_cmd
+	   replica_identity partition_cmd index_partition_cmd index_alter_cmd
 %type <list>	alter_table_cmds alter_type_cmds
 %type <list>    alter_identity_column_option_list
 %type <defelt>  alter_identity_column_option
@@ -483,6 +483,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 %type <boolean> opt_unique opt_verbose opt_full
 %type <boolean> opt_freeze opt_analyze opt_default
 %type <defelt>	opt_binary copy_delimiter
+%type <boolean>  opt_index_enabled
 
 %type <boolean> copy_from opt_program
 
@@ -2149,6 +2150,24 @@ AlterTableStmt:
 					n->nowait = $13;
 					$$ = (Node *) n;
 				}
+		| ALTER INDEX qualified_name index_alter_cmd
+				{
+					AlterTableStmt *n = makeNode(AlterTableStmt);
+					n->relation = $3;
+					n->cmds = list_make1($4);
+					n->objtype = OBJECT_INDEX;
+					n->missing_ok = false;
+					$$ = (Node *) n;
+				}
+		| ALTER INDEX IF_P EXISTS qualified_name index_alter_cmd
+				{
+					AlterTableStmt *n = makeNode(AlterTableStmt);
+					n->relation = $5;
+					n->cmds = list_make1($6);
+					n->objtype = OBJECT_INDEX;
+					n->missing_ok = true;
+					$$ = (Node *) n;
+				}
 		|	ALTER INDEX qualified_name alter_table_cmds
 				{
 					AlterTableStmt *n = makeNode(AlterTableStmt);
@@ -2374,6 +2393,21 @@ index_partition_cmd:
 				}
 		;
 
+index_alter_cmd:
+		/* ALTER INDEX <name> ENABLE|DISABLE */
+		ENABLE_P
+			{
+				AlterTableCmd *n = makeNode(AlterTableCmd);
+				n->subtype = AT_EnableIndex;
+				$$ = (Node *) n;
+			}
+		| DISABLE_P
+			{
+				AlterTableCmd *n = makeNode(AlterTableCmd);
+				n->subtype = AT_DisableIndex;
+				$$ = (Node *) n;
+			}
+		;
 alter_table_cmd:
 			/* ALTER TABLE <name> ADD <coldef> */
 			ADD_P columnDef
@@ -8129,7 +8163,7 @@ defacl_privilege_target:
 
 IndexStmt:	CREATE opt_unique INDEX opt_concurrently opt_single_name
 			ON relation_expr access_method_clause '(' index_params ')'
-			opt_include opt_unique_null_treatment opt_reloptions OptTableSpace where_clause
+			opt_include opt_unique_null_treatment opt_reloptions OptTableSpace where_clause opt_index_enabled
 				{
 					IndexStmt *n = makeNode(IndexStmt);
 
@@ -8144,6 +8178,7 @@ IndexStmt:	CREATE opt_unique INDEX opt_concurrently opt_single_name
 					n->options = $14;
 					n->tableSpace = $15;
 					n->whereClause = $16;
+					n->isenabled = $17;
 					n->excludeOpNames = NIL;
 					n->idxcomment = NULL;
 					n->indexOid = InvalidOid;
@@ -8161,7 +8196,7 @@ IndexStmt:	CREATE opt_unique INDEX opt_concurrently opt_single_name
 				}
 			| CREATE opt_unique INDEX opt_concurrently IF_P NOT EXISTS name
 			ON relation_expr access_method_clause '(' index_params ')'
-			opt_include opt_unique_null_treatment opt_reloptions OptTableSpace where_clause
+			opt_include opt_unique_null_treatment opt_reloptions OptTableSpace where_clause opt_index_enabled
 				{
 					IndexStmt *n = makeNode(IndexStmt);
 
@@ -8176,6 +8211,7 @@ IndexStmt:	CREATE opt_unique INDEX opt_concurrently opt_single_name
 					n->options = $17;
 					n->tableSpace = $18;
 					n->whereClause = $19;
+					n->isenabled = $20;
 					n->excludeOpNames = NIL;
 					n->idxcomment = NULL;
 					n->indexOid = InvalidOid;
@@ -8198,6 +8234,12 @@ opt_unique:
 			| /*EMPTY*/								{ $$ = false; }
 		;
 
+opt_index_enabled:
+			ENABLE_P                      { $$ = true; }
+			| DISABLE_P                   { $$ = false; }
+			| /*EMPTY*/                 	{ $$ = true; }
+		;
+
 access_method_clause:
 			USING name								{ $$ = $2; }
 			| /*EMPTY*/								{ $$ = DEFAULT_INDEX_TYPE; }
diff --git a/src/backend/parser/parse_utilcmd.c b/src/backend/parser/parse_utilcmd.c
index 0f324ee4e31..ddcd69e6114 100644
--- a/src/backend/parser/parse_utilcmd.c
+++ b/src/backend/parser/parse_utilcmd.c
@@ -1736,6 +1736,7 @@ generateClonedIndexStmt(RangeVar *heapRel, Relation source_idx,
 	index->concurrent = false;
 	index->if_not_exists = false;
 	index->reset_default_tblspc = false;
+	index->isenabled = idxrec->indisenabled;
 
 	/*
 	 * We don't try to preserve the name of the source index; instead, just
@@ -2357,6 +2358,8 @@ transformIndexConstraint(Constraint *constraint, CreateStmtContext *cxt)
 	index->concurrent = false;
 	index->if_not_exists = false;
 	index->reset_default_tblspc = constraint->reset_default_tblspc;
+	/* Ensure indexes for constraints are created as enabled by default */
+	index->isenabled = true;
 
 	/*
 	 * If it's ALTER TABLE ADD CONSTRAINT USING INDEX, look up the index and
diff --git a/src/backend/utils/adt/ruleutils.c b/src/backend/utils/adt/ruleutils.c
index 2194ab3dfa5..34b6a685c30 100644
--- a/src/backend/utils/adt/ruleutils.c
+++ b/src/backend/utils/adt/ruleutils.c
@@ -1559,6 +1559,10 @@ pg_get_indexdef_worker(Oid indexrelid, int colno,
 			else
 				appendStringInfo(&buf, " WHERE %s", str);
 		}
+
+		/* Add DISABLE clause if the index is disabled */
+		if (!idxrec->indisenabled)
+				appendStringInfoString(&buf, " DISABLE");
 	}
 
 	/* Clean up */
diff --git a/src/backend/utils/cache/relcache.c b/src/backend/utils/cache/relcache.c
index 422509f18d7..497ef37aca8 100644
--- a/src/backend/utils/cache/relcache.c
+++ b/src/backend/utils/cache/relcache.c
@@ -2323,6 +2323,7 @@ RelationReloadIndexInfo(Relation relation)
 		relation->rd_index->indisready = index->indisready;
 		relation->rd_index->indislive = index->indislive;
 		relation->rd_index->indisreplident = index->indisreplident;
+		relation->rd_index->indisenabled = index->indisenabled;
 
 		/* Copy xmin too, as that is needed to make sense of indcheckxmin */
 		HeapTupleHeaderSetXmin(relation->rd_indextuple->t_data,
diff --git a/src/include/catalog/index.h b/src/include/catalog/index.h
index 2dea96f47c3..8a47cfd174f 100644
--- a/src/include/catalog/index.h
+++ b/src/include/catalog/index.h
@@ -65,6 +65,7 @@ extern void index_check_primary_key(Relation heapRel,
 #define	INDEX_CREATE_IF_NOT_EXISTS			(1 << 4)
 #define	INDEX_CREATE_PARTITIONED			(1 << 5)
 #define INDEX_CREATE_INVALID				(1 << 6)
+#define INDEX_CREATE_ENABLED        (1 << 7)
 
 extern Oid	index_create(Relation heapRelation,
 						 const char *indexRelationName,
@@ -175,7 +176,6 @@ extern void RestoreReindexState(const void *reindexstate);
 
 extern void IndexSetParentIndex(Relation partitionIdx, Oid parentOid);
 
-
 /*
  * itemptr_encode - Encode ItemPointer as int64/int8
  *
diff --git a/src/include/catalog/pg_index.h b/src/include/catalog/pg_index.h
index 6c89639a9e4..b0c7e5f3654 100644
--- a/src/include/catalog/pg_index.h
+++ b/src/include/catalog/pg_index.h
@@ -44,6 +44,7 @@ CATALOG(pg_index,2610,IndexRelationId) BKI_SCHEMA_MACRO
 	bool		indisready;		/* is this index ready for inserts? */
 	bool		indislive;		/* is this index alive at all? */
 	bool		indisreplident; /* is this index the identity for replication? */
+	bool		indisenabled;	/* is this index enabled for use by queries? */
 
 	/* variable-length fields start here, but we allow direct access to indkey */
 	int2vector	indkey BKI_FORCE_NOT_NULL;	/* column numbers of indexed cols,
diff --git a/src/include/nodes/parsenodes.h b/src/include/nodes/parsenodes.h
index 0f9462493e3..5054f9f8bb4 100644
--- a/src/include/nodes/parsenodes.h
+++ b/src/include/nodes/parsenodes.h
@@ -2423,6 +2423,8 @@ typedef enum AlterTableType
 	AT_SetIdentity,				/* SET identity column options */
 	AT_DropIdentity,			/* DROP IDENTITY */
 	AT_ReAddStatistics,			/* internal to commands/tablecmds.c */
+	AT_EnableIndex,					/* ENABLE INDEX */
+	AT_DisableIndex,				/* DISABLE INDEX */
 } AlterTableType;
 
 typedef struct ReplicaIdentityStmt
@@ -3402,6 +3404,7 @@ typedef struct IndexStmt
 	bool		if_not_exists;	/* just do nothing if index already exists? */
 	bool		reset_default_tblspc;	/* reset default_tablespace prior to
 										 * executing */
+  bool		isenabled;		/* true if ENABLE (default), false if DISABLE */
 } IndexStmt;
 
 /* ----------------------
diff --git a/src/include/nodes/pathnodes.h b/src/include/nodes/pathnodes.h
index add0f9e45fc..a0ebd517011 100644
--- a/src/include/nodes/pathnodes.h
+++ b/src/include/nodes/pathnodes.h
@@ -1210,6 +1210,8 @@ struct IndexOptInfo
 	/* AM's cost estimator */
 	/* Rather than include amapi.h here, we declare amcostestimate like this */
 	void		(*amcostestimate) (struct PlannerInfo *, struct IndexPath *, double, Cost *, Cost *, Selectivity *, double *, double *) pg_node_attr(read_write_ignore);
+	/* true if this index is enabled */
+	bool		enabled;
 };
 
 /*
diff --git a/src/test/regress/expected/create_index.out b/src/test/regress/expected/create_index.out
index 1904eb65bb9..8e4952ca605 100644
--- a/src/test/regress/expected/create_index.out
+++ b/src/test/regress/expected/create_index.out
@@ -3318,6 +3318,511 @@ ERROR:  REINDEX SCHEMA cannot run inside a transaction block
 END;
 -- concurrently
 REINDEX SCHEMA CONCURRENTLY schema_to_reindex;
+-- Test enable/disable functionality for indexes
+CREATE TABLE index_test(
+    id INT PRIMARY KEY,
+    data TEXT,
+    num INT,
+    vector INT[],
+    range INT4RANGE
+);
+INSERT INTO index_test
+SELECT
+    g,
+    'data ' || g,
+    g % 100,
+    ARRAY[g, g+1, g+2],
+    int4range(g, g+10)
+FROM generate_series(1, 1000) g;
+-- Function for testing
+CREATE FUNCTION get_data_length(text) RETURNS INT AS $$
+    SELECT length($1);
+$$ LANGUAGE SQL IMMUTABLE;
+-- Helper function to show index status
+CREATE OR REPLACE FUNCTION show_index_status(index_name text)
+RETURNS TABLE (
+    indexrelid regclass,
+    indisvalid boolean,
+    indisready boolean,
+    indislive boolean,
+    indisenabled boolean
+) AS $$
+BEGIN
+    RETURN QUERY EXECUTE format('
+        SELECT indexrelid::regclass, indisvalid, indisready, indislive, indisenabled
+        FROM pg_index
+        WHERE indexrelid = %L::regclass', index_name);
+END;
+$$ LANGUAGE plpgsql;
+-- Create and test each index type
+-- 1. Basic single-column index
+CREATE INDEX idx_single ON index_test(data);
+SELECT show_index_status('idx_single');
+  show_index_status   
+----------------------
+ (idx_single,t,t,t,t)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE data = 'data 500';
+                  QUERY PLAN                   
+-----------------------------------------------
+ Bitmap Heap Scan on index_test
+   Recheck Cond: (data = 'data 500'::text)
+   ->  Bitmap Index Scan on idx_single
+         Index Cond: (data = 'data 500'::text)
+(4 rows)
+
+ALTER INDEX idx_single DISABLE;
+SELECT show_index_status('idx_single');
+  show_index_status   
+----------------------
+ (idx_single,t,t,t,f)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE data = 'data 500';
+             QUERY PLAN              
+-------------------------------------
+ Seq Scan on index_test
+   Filter: (data = 'data 500'::text)
+(2 rows)
+
+ALTER INDEX idx_single ENABLE;
+SELECT show_index_status('idx_single');
+  show_index_status   
+----------------------
+ (idx_single,t,t,t,t)
+(1 row)
+
+-- 2. Multi-column index
+CREATE INDEX idx_multi ON index_test(num, data);
+SELECT show_index_status('idx_multi');
+  show_index_status  
+---------------------
+ (idx_multi,t,t,t,t)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE num = 50 AND data > 'data 500';
+                           QUERY PLAN                           
+----------------------------------------------------------------
+ Bitmap Heap Scan on index_test
+   Recheck Cond: ((num = 50) AND (data > 'data 500'::text))
+   ->  Bitmap Index Scan on idx_multi
+         Index Cond: ((num = 50) AND (data > 'data 500'::text))
+(4 rows)
+
+ALTER INDEX idx_multi DISABLE;
+SELECT show_index_status('idx_multi');
+  show_index_status  
+---------------------
+ (idx_multi,t,t,t,f)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE num = 50 AND data > 'data 500';
+                      QUERY PLAN                      
+------------------------------------------------------
+ Seq Scan on index_test
+   Filter: ((data > 'data 500'::text) AND (num = 50))
+(2 rows)
+
+ALTER INDEX idx_multi ENABLE;
+SELECT show_index_status('idx_multi');
+  show_index_status  
+---------------------
+ (idx_multi,t,t,t,t)
+(1 row)
+
+-- 3. Partial index
+CREATE INDEX idx_partial ON index_test(num) WHERE num < 50;
+SELECT show_index_status('idx_partial');
+   show_index_status   
+-----------------------
+ (idx_partial,t,t,t,t)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE num = 25;
+               QUERY PLAN               
+----------------------------------------
+ Bitmap Heap Scan on index_test
+   Recheck Cond: (num = 25)
+   ->  Bitmap Index Scan on idx_partial
+         Index Cond: (num = 25)
+(4 rows)
+
+ALTER INDEX idx_partial DISABLE;
+SELECT show_index_status('idx_partial');
+   show_index_status   
+-----------------------
+ (idx_partial,t,t,t,f)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE num = 25;
+              QUERY PLAN              
+--------------------------------------
+ Bitmap Heap Scan on index_test
+   Recheck Cond: (num = 25)
+   ->  Bitmap Index Scan on idx_multi
+         Index Cond: (num = 25)
+(4 rows)
+
+ALTER INDEX idx_partial ENABLE;
+SELECT show_index_status('idx_partial');
+   show_index_status   
+-----------------------
+ (idx_partial,t,t,t,t)
+(1 row)
+
+-- 4. Expression index
+CREATE INDEX idx_expression ON index_test((lower(data)));
+SELECT show_index_status('idx_expression');
+    show_index_status     
+--------------------------
+ (idx_expression,t,t,t,t)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE lower(data) = 'data 500';
+                      QUERY PLAN                      
+------------------------------------------------------
+ Bitmap Heap Scan on index_test
+   Recheck Cond: (lower(data) = 'data 500'::text)
+   ->  Bitmap Index Scan on idx_expression
+         Index Cond: (lower(data) = 'data 500'::text)
+(4 rows)
+
+ALTER INDEX idx_expression DISABLE;
+SELECT show_index_status('idx_expression');
+    show_index_status     
+--------------------------
+ (idx_expression,t,t,t,f)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE lower(data) = 'data 500';
+                 QUERY PLAN                 
+--------------------------------------------
+ Seq Scan on index_test
+   Filter: (lower(data) = 'data 500'::text)
+(2 rows)
+
+ALTER INDEX idx_expression ENABLE;
+SELECT show_index_status('idx_expression');
+    show_index_status     
+--------------------------
+ (idx_expression,t,t,t,t)
+(1 row)
+
+-- 5. GIN index
+CREATE INDEX idx_gin ON index_test USING gin(vector);
+SELECT show_index_status('idx_gin');
+ show_index_status 
+-------------------
+ (idx_gin,t,t,t,t)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE vector @> ARRAY[500];
+                     QUERY PLAN                     
+----------------------------------------------------
+ Bitmap Heap Scan on index_test
+   Recheck Cond: (vector @> '{500}'::integer[])
+   ->  Bitmap Index Scan on idx_gin
+         Index Cond: (vector @> '{500}'::integer[])
+(4 rows)
+
+ALTER INDEX idx_gin DISABLE;
+SELECT show_index_status('idx_gin');
+ show_index_status 
+-------------------
+ (idx_gin,t,t,t,f)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE vector @> ARRAY[500];
+                QUERY PLAN                
+------------------------------------------
+ Seq Scan on index_test
+   Filter: (vector @> '{500}'::integer[])
+(2 rows)
+
+ALTER INDEX idx_gin ENABLE;
+SELECT show_index_status('idx_gin');
+ show_index_status 
+-------------------
+ (idx_gin,t,t,t,t)
+(1 row)
+
+-- 6. GiST index
+CREATE INDEX idx_gist ON index_test USING gist(range);
+SELECT show_index_status('idx_gist');
+ show_index_status  
+--------------------
+ (idx_gist,t,t,t,t)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE range && int4range(100, 110);
+                      QUERY PLAN                       
+-------------------------------------------------------
+ Bitmap Heap Scan on index_test
+   Recheck Cond: (range && '[100,110)'::int4range)
+   ->  Bitmap Index Scan on idx_gist
+         Index Cond: (range && '[100,110)'::int4range)
+(4 rows)
+
+ALTER INDEX idx_gist DISABLE;
+SELECT show_index_status('idx_gist');
+ show_index_status  
+--------------------
+ (idx_gist,t,t,t,f)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE range && int4range(100, 110);
+                 QUERY PLAN                  
+---------------------------------------------
+ Seq Scan on index_test
+   Filter: (range && '[100,110)'::int4range)
+(2 rows)
+
+ALTER INDEX idx_gist ENABLE;
+SELECT show_index_status('idx_gist');
+ show_index_status  
+--------------------
+ (idx_gist,t,t,t,t)
+(1 row)
+
+-- 7. Covering index
+CREATE INDEX idx_covering ON index_test(num) INCLUDE (data);
+SELECT show_index_status('idx_covering');
+   show_index_status    
+------------------------
+ (idx_covering,t,t,t,t)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT num, data FROM index_test WHERE num = 50;
+               QUERY PLAN                
+-----------------------------------------
+ Bitmap Heap Scan on index_test
+   Recheck Cond: (num = 50)
+   ->  Bitmap Index Scan on idx_covering
+         Index Cond: (num = 50)
+(4 rows)
+
+ALTER INDEX idx_covering DISABLE;
+SELECT show_index_status('idx_covering');
+   show_index_status    
+------------------------
+ (idx_covering,t,t,t,f)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT num, data FROM index_test WHERE num = 50;
+              QUERY PLAN              
+--------------------------------------
+ Bitmap Heap Scan on index_test
+   Recheck Cond: (num = 50)
+   ->  Bitmap Index Scan on idx_multi
+         Index Cond: (num = 50)
+(4 rows)
+
+ALTER INDEX idx_covering ENABLE;
+SELECT show_index_status('idx_covering');
+   show_index_status    
+------------------------
+ (idx_covering,t,t,t,t)
+(1 row)
+
+-- 8. Unique index
+CREATE UNIQUE INDEX idx_unique ON index_test(id, data);
+SELECT show_index_status('idx_unique');
+  show_index_status   
+----------------------
+ (idx_unique,t,t,t,t)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE id = 500 AND data = 'data 500';
+                        QUERY PLAN                        
+----------------------------------------------------------
+ Index Scan using idx_unique on index_test
+   Index Cond: ((id = 500) AND (data = 'data 500'::text))
+(2 rows)
+
+ALTER INDEX idx_unique DISABLE;
+SELECT show_index_status('idx_unique');
+  show_index_status   
+----------------------
+ (idx_unique,t,t,t,f)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE id = 500 AND data = 'data 500';
+                   QUERY PLAN                   
+------------------------------------------------
+ Index Scan using index_test_pkey on index_test
+   Index Cond: (id = 500)
+   Filter: (data = 'data 500'::text)
+(3 rows)
+
+ALTER INDEX idx_unique ENABLE;
+SELECT show_index_status('idx_unique');
+  show_index_status   
+----------------------
+ (idx_unique,t,t,t,t)
+(1 row)
+
+-- 9. Function-based index
+CREATE INDEX idx_func ON index_test(get_data_length(data));
+SELECT show_index_status('idx_func');
+ show_index_status  
+--------------------
+ (idx_func,t,t,t,t)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE get_data_length(data) = 10;
+               QUERY PLAN                
+-----------------------------------------
+ Bitmap Heap Scan on index_test
+   Recheck Cond: (length(data) = 10)
+   ->  Bitmap Index Scan on idx_func
+         Index Cond: (length(data) = 10)
+(4 rows)
+
+ALTER INDEX idx_func DISABLE;
+SELECT show_index_status('idx_func');
+ show_index_status  
+--------------------
+ (idx_func,t,t,t,f)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE get_data_length(data) = 10;
+          QUERY PLAN           
+-------------------------------
+ Seq Scan on index_test
+   Filter: (length(data) = 10)
+(2 rows)
+
+ALTER INDEX idx_func ENABLE;
+SELECT show_index_status('idx_func');
+ show_index_status  
+--------------------
+ (idx_func,t,t,t,t)
+(1 row)
+
+-- 10. Join index
+CREATE TABLE join_test (id INT PRIMARY KEY, ref_id INT);
+INSERT INTO join_test SELECT g, g % 100 FROM generate_series(1, 1000) g;
+CREATE INDEX idx_join ON join_test(ref_id);
+SELECT show_index_status('idx_join');
+ show_index_status  
+--------------------
+ (idx_join,t,t,t,t)
+(1 row)
+
+EXPLAIN (COSTS OFF)
+SELECT jt.id, it.data
+FROM join_test jt
+JOIN index_test it ON jt.ref_id = it.num
+WHERE jt.id BETWEEN 100 AND 200;
+                          QUERY PLAN                           
+---------------------------------------------------------------
+ Hash Join
+   Hash Cond: (it.num = jt.ref_id)
+   ->  Seq Scan on index_test it
+   ->  Hash
+         ->  Bitmap Heap Scan on join_test jt
+               Recheck Cond: ((id >= 100) AND (id <= 200))
+               ->  Bitmap Index Scan on join_test_pkey
+                     Index Cond: ((id >= 100) AND (id <= 200))
+(8 rows)
+
+-- Disable all indexes to force seq scan
+ALTER INDEX idx_join DISABLE;
+ALTER INDEX join_test_pkey DISABLE;
+SELECT show_index_status('idx_join');
+ show_index_status  
+--------------------
+ (idx_join,t,t,t,f)
+(1 row)
+
+SELECT show_index_status('join_test_pkey');
+    show_index_status     
+--------------------------
+ (join_test_pkey,t,t,t,f)
+(1 row)
+
+EXPLAIN (COSTS OFF)
+SELECT jt.id, it.data
+FROM join_test jt
+JOIN index_test it ON jt.ref_id = it.num
+WHERE jt.id BETWEEN 100 AND 200;
+                     QUERY PLAN                      
+-----------------------------------------------------
+ Hash Join
+   Hash Cond: (it.num = jt.ref_id)
+   ->  Seq Scan on index_test it
+   ->  Hash
+         ->  Seq Scan on join_test jt
+               Filter: ((id >= 100) AND (id <= 200))
+(6 rows)
+
+ALTER INDEX idx_join ENABLE;
+ALTER INDEX join_test_pkey ENABLE;
+SELECT show_index_status('idx_join');
+ show_index_status  
+--------------------
+ (idx_join,t,t,t,t)
+(1 row)
+
+SELECT show_index_status('join_test_pkey');
+    show_index_status     
+--------------------------
+ (join_test_pkey,t,t,t,t)
+(1 row)
+
+-- Test REINDEX CONCURRENTLY
+REINDEX INDEX CONCURRENTLY idx_join;
+SELECT show_index_status('idx_join');
+ show_index_status  
+--------------------
+ (idx_join,t,t,t,t)
+(1 row)
+
+ALTER INDEX idx_join DISABLE;
+SELECT show_index_status('idx_join');
+ show_index_status  
+--------------------
+ (idx_join,t,t,t,f)
+(1 row)
+
+REINDEX INDEX CONCURRENTLY idx_join;
+SELECT show_index_status('idx_join');
+ show_index_status  
+--------------------
+ (idx_join,t,t,t,f)
+(1 row)
+
+SELECT pg_get_indexdef('idx_join'::regclass);
+                                  pg_get_indexdef                                  
+-----------------------------------------------------------------------------------
+ CREATE INDEX idx_join ON schema_to_reindex.join_test USING btree (ref_id) DISABLE
+(1 row)
+
+ALTER INDEX idx_join ENABLE;
+SELECT pg_get_indexdef('idx_join'::regclass);
+                              pg_get_indexdef                              
+---------------------------------------------------------------------------
+ CREATE INDEX idx_join ON schema_to_reindex.join_test USING btree (ref_id)
+(1 row)
+
+-- Test enable/disable index with indcheckxmin being true
+CREATE TABLE indcheckxmin_test(id int PRIMARY KEY);
+INSERT INTO indcheckxmin_test VALUES (1), (2), (3);
+CREATE INDEX CONCURRENTLY idx_checkxmin ON indcheckxmin_test(id);
+BEGIN;
+-- Simulate indcheckxmin being true
+UPDATE pg_index SET indcheckxmin = true WHERE indexrelid = 'idx_checkxmin'::regclass;
+ALTER INDEX idx_checkxmin DISABLE;  -- expect fail
+ERROR:  cannot enable/disable index while indcheckxmin is true
+HINT:  Wait for all transactions that might see inconsistent HOT chains to complete
+ROLLBACK;
+-- Clean up
+DROP TABLE index_test;
+DROP TABLE join_test;
+DROP FUNCTION get_data_length;
+DROP FUNCTION show_index_status;
+DROP TABLE indcheckxmin_test CASCADE;
 -- Failure for unauthorized user
 CREATE ROLE regress_reindexuser NOLOGIN;
 SET SESSION ROLE regress_reindexuser;
diff --git a/src/test/regress/sql/create_index.sql b/src/test/regress/sql/create_index.sql
index c085e05f052..2d61ff2f9bb 100644
--- a/src/test/regress/sql/create_index.sql
+++ b/src/test/regress/sql/create_index.sql
@@ -1410,6 +1410,198 @@ END;
 -- concurrently
 REINDEX SCHEMA CONCURRENTLY schema_to_reindex;
 
+-- Test enable/disable functionality for indexes
+
+CREATE TABLE index_test(
+    id INT PRIMARY KEY,
+    data TEXT,
+    num INT,
+    vector INT[],
+    range INT4RANGE
+);
+
+INSERT INTO index_test
+SELECT
+    g,
+    'data ' || g,
+    g % 100,
+    ARRAY[g, g+1, g+2],
+    int4range(g, g+10)
+FROM generate_series(1, 1000) g;
+
+-- Function for testing
+CREATE FUNCTION get_data_length(text) RETURNS INT AS $$
+    SELECT length($1);
+$$ LANGUAGE SQL IMMUTABLE;
+
+-- Helper function to show index status
+CREATE OR REPLACE FUNCTION show_index_status(index_name text)
+RETURNS TABLE (
+    indexrelid regclass,
+    indisvalid boolean,
+    indisready boolean,
+    indislive boolean,
+    indisenabled boolean
+) AS $$
+BEGIN
+    RETURN QUERY EXECUTE format('
+        SELECT indexrelid::regclass, indisvalid, indisready, indislive, indisenabled
+        FROM pg_index
+        WHERE indexrelid = %L::regclass', index_name);
+END;
+$$ LANGUAGE plpgsql;
+
+-- Create and test each index type
+-- 1. Basic single-column index
+CREATE INDEX idx_single ON index_test(data);
+SELECT show_index_status('idx_single');
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE data = 'data 500';
+ALTER INDEX idx_single DISABLE;
+SELECT show_index_status('idx_single');
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE data = 'data 500';
+ALTER INDEX idx_single ENABLE;
+SELECT show_index_status('idx_single');
+
+-- 2. Multi-column index
+CREATE INDEX idx_multi ON index_test(num, data);
+SELECT show_index_status('idx_multi');
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE num = 50 AND data > 'data 500';
+ALTER INDEX idx_multi DISABLE;
+SELECT show_index_status('idx_multi');
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE num = 50 AND data > 'data 500';
+ALTER INDEX idx_multi ENABLE;
+SELECT show_index_status('idx_multi');
+
+-- 3. Partial index
+CREATE INDEX idx_partial ON index_test(num) WHERE num < 50;
+SELECT show_index_status('idx_partial');
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE num = 25;
+ALTER INDEX idx_partial DISABLE;
+SELECT show_index_status('idx_partial');
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE num = 25;
+ALTER INDEX idx_partial ENABLE;
+SELECT show_index_status('idx_partial');
+
+-- 4. Expression index
+CREATE INDEX idx_expression ON index_test((lower(data)));
+SELECT show_index_status('idx_expression');
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE lower(data) = 'data 500';
+ALTER INDEX idx_expression DISABLE;
+SELECT show_index_status('idx_expression');
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE lower(data) = 'data 500';
+ALTER INDEX idx_expression ENABLE;
+SELECT show_index_status('idx_expression');
+
+-- 5. GIN index
+CREATE INDEX idx_gin ON index_test USING gin(vector);
+SELECT show_index_status('idx_gin');
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE vector @> ARRAY[500];
+ALTER INDEX idx_gin DISABLE;
+SELECT show_index_status('idx_gin');
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE vector @> ARRAY[500];
+ALTER INDEX idx_gin ENABLE;
+SELECT show_index_status('idx_gin');
+
+-- 6. GiST index
+CREATE INDEX idx_gist ON index_test USING gist(range);
+SELECT show_index_status('idx_gist');
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE range && int4range(100, 110);
+ALTER INDEX idx_gist DISABLE;
+SELECT show_index_status('idx_gist');
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE range && int4range(100, 110);
+ALTER INDEX idx_gist ENABLE;
+SELECT show_index_status('idx_gist');
+
+-- 7. Covering index
+CREATE INDEX idx_covering ON index_test(num) INCLUDE (data);
+SELECT show_index_status('idx_covering');
+EXPLAIN (COSTS OFF) SELECT num, data FROM index_test WHERE num = 50;
+ALTER INDEX idx_covering DISABLE;
+SELECT show_index_status('idx_covering');
+EXPLAIN (COSTS OFF) SELECT num, data FROM index_test WHERE num = 50;
+ALTER INDEX idx_covering ENABLE;
+SELECT show_index_status('idx_covering');
+
+-- 8. Unique index
+CREATE UNIQUE INDEX idx_unique ON index_test(id, data);
+SELECT show_index_status('idx_unique');
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE id = 500 AND data = 'data 500';
+ALTER INDEX idx_unique DISABLE;
+SELECT show_index_status('idx_unique');
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE id = 500 AND data = 'data 500';
+ALTER INDEX idx_unique ENABLE;
+SELECT show_index_status('idx_unique');
+
+-- 9. Function-based index
+CREATE INDEX idx_func ON index_test(get_data_length(data));
+SELECT show_index_status('idx_func');
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE get_data_length(data) = 10;
+ALTER INDEX idx_func DISABLE;
+SELECT show_index_status('idx_func');
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE get_data_length(data) = 10;
+ALTER INDEX idx_func ENABLE;
+SELECT show_index_status('idx_func');
+
+-- 10. Join index
+CREATE TABLE join_test (id INT PRIMARY KEY, ref_id INT);
+INSERT INTO join_test SELECT g, g % 100 FROM generate_series(1, 1000) g;
+CREATE INDEX idx_join ON join_test(ref_id);
+SELECT show_index_status('idx_join');
+
+EXPLAIN (COSTS OFF)
+SELECT jt.id, it.data
+FROM join_test jt
+JOIN index_test it ON jt.ref_id = it.num
+WHERE jt.id BETWEEN 100 AND 200;
+
+-- Disable all indexes to force seq scan
+ALTER INDEX idx_join DISABLE;
+ALTER INDEX join_test_pkey DISABLE;
+SELECT show_index_status('idx_join');
+SELECT show_index_status('join_test_pkey');
+
+EXPLAIN (COSTS OFF)
+SELECT jt.id, it.data
+FROM join_test jt
+JOIN index_test it ON jt.ref_id = it.num
+WHERE jt.id BETWEEN 100 AND 200;
+
+ALTER INDEX idx_join ENABLE;
+ALTER INDEX join_test_pkey ENABLE;
+SELECT show_index_status('idx_join');
+SELECT show_index_status('join_test_pkey');
+
+-- Test REINDEX CONCURRENTLY
+REINDEX INDEX CONCURRENTLY idx_join;
+SELECT show_index_status('idx_join');
+
+ALTER INDEX idx_join DISABLE;
+SELECT show_index_status('idx_join');
+REINDEX INDEX CONCURRENTLY idx_join;
+SELECT show_index_status('idx_join');
+
+SELECT pg_get_indexdef('idx_join'::regclass);
+ALTER INDEX idx_join ENABLE;
+SELECT pg_get_indexdef('idx_join'::regclass);
+
+-- Test enable/disable index with indcheckxmin being true
+
+CREATE TABLE indcheckxmin_test(id int PRIMARY KEY);
+INSERT INTO indcheckxmin_test VALUES (1), (2), (3);
+CREATE INDEX CONCURRENTLY idx_checkxmin ON indcheckxmin_test(id);
+BEGIN;
+-- Simulate indcheckxmin being true
+UPDATE pg_index SET indcheckxmin = true WHERE indexrelid = 'idx_checkxmin'::regclass;
+ALTER INDEX idx_checkxmin DISABLE;  -- expect fail
+ROLLBACK;
+
+-- Clean up
+DROP TABLE index_test;
+DROP TABLE join_test;
+DROP FUNCTION get_data_length;
+DROP FUNCTION show_index_status;
+DROP TABLE indcheckxmin_test CASCADE;
+
 -- Failure for unauthorized user
 CREATE ROLE regress_reindexuser NOLOGIN;
 SET SESSION ROLE regress_reindexuser;
-- 
2.37.1 (Apple Git-137.1)

#48Shayon Mukherjee
shayonj@gmail.com
In reply to: Shayon Mukherjee (#47)
1 attachment(s)
Re: Proposal to Enable/Disable Index using ALTER INDEX (with patch)

On Fri, Dec 6, 2024 at 11:24 AM Shayon Mukherjee <shayonj@gmail.com> wrote:

The patch is also rebased against the latest master and passing in CI.
Would love to receive any further feedback on it.

Rebased the last patch against the latest master from today as a v5. No
other changes since last post.

Shayon

Attachments:

v5-0001-Introduce-the-ability-to-enable-disable-indexes-u.patchapplication/octet-stream; name=v5-0001-Introduce-the-ability-to-enable-disable-indexes-u.patchDownload
From 3816092c1ae8841d3f6ea4e9893aea53ae972faf Mon Sep 17 00:00:00 2001
From: Shayon Mukherjee <shayonj@gmail.com>
Date: Thu, 17 Oct 2024 10:04:13 -0400
Subject: [PATCH v5] Introduce the ability to enable/disable indexes using
 ALTER INDEX

This patch introduces the ability to enable or disable indexes using ALTER INDEX
and CREATE INDEX commands.

Original motivation for the problem and proposal for a patch
can be found at [1].

This patch passes all the existing specs and the newly added regression tests. The patch
is ready for review and test. It compiles, so the can patch can be applied for testing as well.

Implementation details:

- New Grammar:
  * ALTER INDEX ... ENABLE/DISABLE
  * CREATE INDEX ... DISABLE

- Default state is enabled. Indexes are only disabled when explicitly
  instructed via CREATE INDEX ... DISABLE or ALTER INDEX ... DISABLE.

- Primary Key and Unique constraint indexes are always enabled as well. The
  ENABLE/DISABLE grammar is not supported for these types of indexes. They can
  be later disabled via ALTER INDEX ... ENABLE/DISABLE.

- ALTER INDEX ... ENABLE/DISABLE performs update on the relevant row in pg_index
  catalog

- pg_get_indexdef() support the new functionality and grammar. This change is
  reflected in \d output for tables and pg_dump. We show the DISABLE syntax accordingly.

- Updated create_index.sql regression test to cover the new grammar and verify
  that disabled indexes are not used in queries. The test CATALOG_VERSION_NO

  - Basic single-column and multi-column indexes
  - Partial indexes
  - Expression indexes
  - Join indexes
  - GIN and GiST indexes
  - Covering indexes
  - Range indexes
  - Unique indexes and constraints

- Adds a new enabled attribute to the IndexOptInfo structure.

- Modifies get_relation_info in plancat.c to skip disabled indexes entirely, thus reducing the number of places we need to check if an index is disabled or not. Inspired by the conversations start at [2].
  - I chose to modify the logic within get_relation_info as compared to, say, reducing the cost to make the planner not consider an index during planning, mostly to keep the number of changes being introduced to a minimum and also the logic itself being self-contained and easier to under perhaps (?).

- No changes are made to stop the index from getting rebuilt. This way we ensure no
  data miss or corruption when index is re-nabled.

- TOAST indexes are supported and enabled by default as well.

- REINDEX CONCURRENTLY is supported as well and existing state of pg_index.indisenabled
  is carried over accordingly.

- See the changes in create_index.sql to get an idea of the grammar and sql statements.

- See the changes in create_index.out to get an idea of the catalogue states and EXPLAIN
  output to see when an index is getting used or isn't (when disabled).

- Incorporated DavidR's feedback from [3] around documentation and also you will see that by skip disabled indexes entirely from get_relation_info in plancat.c (as mentioned above), we address the other mentioned issues as well.

- Lastly, protects against the case where indcheckxmin is true by raising ERRCODE_OBJECT_NOT_IN_PREREQUISITE_STATE.

Looking forward to any and all feedback on this patch, including but not limited to code quality, tests, fundamental logic.

[1] https://www.postgresql.org/message-id/CANqtF-oXKe0M%3D0QOih6H%2BsZRjE2BWAbkW_1%2B9nMEAMLxUJg5jA%40mail.gmail.com
[2] https://www.postgresql.org/message-id/3465209.1727202064%40sss.pgh.pa.us
[3] https://www.postgresql.org/message-id/CAApHDvpUNu%3DiVcdJ74sypvgeaCF%2Btfpyb8VRhZaF7DTd1xVr7g%40mail.gmail.com
---
 doc/src/sgml/catalogs.sgml                 |  11 +
 doc/src/sgml/ref/alter_index.sgml          |  43 ++
 doc/src/sgml/ref/create_index.sgml         |  29 ++
 src/backend/bootstrap/bootparse.y          |   2 +
 src/backend/catalog/index.c                |  31 +-
 src/backend/catalog/toasting.c             |   2 +-
 src/backend/commands/indexcmds.c           |   4 +
 src/backend/commands/tablecmds.c           |  67 ++-
 src/backend/optimizer/util/plancat.c       |  13 +
 src/backend/parser/gram.y                  |  48 +-
 src/backend/parser/parse_utilcmd.c         |   3 +
 src/backend/utils/adt/ruleutils.c          |   4 +
 src/backend/utils/cache/relcache.c         |   1 +
 src/include/catalog/index.h                |   2 +-
 src/include/catalog/pg_index.h             |   1 +
 src/include/nodes/parsenodes.h             |   3 +
 src/include/nodes/pathnodes.h              |   2 +
 src/test/regress/expected/create_index.out | 505 +++++++++++++++++++++
 src/test/regress/sql/create_index.sql      | 192 ++++++++
 19 files changed, 953 insertions(+), 10 deletions(-)

diff --git a/doc/src/sgml/catalogs.sgml b/doc/src/sgml/catalogs.sgml
index cc6cf9bef09..f49ef308aba 100644
--- a/doc/src/sgml/catalogs.sgml
+++ b/doc/src/sgml/catalogs.sgml
@@ -4585,6 +4585,17 @@ SCRAM-SHA-256$<replaceable>&lt;iteration count&gt;</replaceable>:<replaceable>&l
        partial index.
       </para></entry>
      </row>
+
+     <row>
+      <entry role="catalog_table_entry"><para role="column_definition">
+       <structfield>indisenabled</structfield> <type>bool</type>
+      </para>
+      <para>
+       If true, the index is currently enabled and should be used for queries.
+       If false, the index is disabled and should not be used for queries,
+       but is still maintained when the table is modified. Default is true.
+      </para></entry>
+     </row>
     </tbody>
    </tgroup>
   </table>
diff --git a/doc/src/sgml/ref/alter_index.sgml b/doc/src/sgml/ref/alter_index.sgml
index 1d42d05d858..04b3b0b9bfe 100644
--- a/doc/src/sgml/ref/alter_index.sgml
+++ b/doc/src/sgml/ref/alter_index.sgml
@@ -31,6 +31,8 @@ ALTER INDEX [ IF EXISTS ] <replaceable class="parameter">name</replaceable> ALTE
     SET STATISTICS <replaceable class="parameter">integer</replaceable>
 ALTER INDEX ALL IN TABLESPACE <replaceable class="parameter">name</replaceable> [ OWNED BY <replaceable class="parameter">role_name</replaceable> [, ... ] ]
     SET TABLESPACE <replaceable class="parameter">new_tablespace</replaceable> [ NOWAIT ]
+ALTER INDEX [ IF EXISTS ] <replaceable class="parameter">name</replaceable> ENABLE
+ALTER INDEX [ IF EXISTS ] <replaceable class="parameter">name</replaceable> DISABLE
 </synopsis>
  </refsynopsisdiv>
 
@@ -159,6 +161,33 @@ ALTER INDEX ALL IN TABLESPACE <replaceable class="parameter">name</replaceable>
     </listitem>
    </varlistentry>
 
+   <varlistentry>
+    <term><literal>ENABLE</literal></term>
+    <listitem>
+     <para>
+      Enable the specified index. The index will be used by the query planner
+      for query optimization. This is the default state for newly created indexes.
+     </para>
+    </listitem>
+   </varlistentry>
+
+   <varlistentry>
+    <term><literal>DISABLE</literal></term>
+    <listitem>
+     <para>
+      Disable the specified index. A disabled index is not used by the query planner
+      for query optimization, but it is still maintained when the underlying table
+      data changes. This can be useful for testing query performance with and without
+      specific indexes, temporarily reducing the overhead of index maintenance
+      during bulk data loading operations, or verifying an index is not being used
+      before dropping it. If performance degrades after disabling an index, it can be
+      easily re-enabled. Before disabling, it's recommended to check
+      <structname>pg_stat_user_indexes</structname>.<structfield>idx_scan</structfield>
+      to identify potentially unused indexes.
+     </para>
+    </listitem>
+   </varlistentry>
+
   </variablelist>
   </para>
 
@@ -301,6 +330,20 @@ CREATE INDEX coord_idx ON measured (x, y, (z + t));
 ALTER INDEX coord_idx ALTER COLUMN 3 SET STATISTICS 1000;
 </programlisting></para>
 
+  <para>
+   To enable an index:
+<programlisting>
+ALTER INDEX idx_name ENABLE;
+</programlisting>
+  </para>
+
+  <para>
+   To disable an index:
+<programlisting>
+ALTER INDEX idx_name DISABLE;
+</programlisting>
+  </para>
+
  </refsect1>
 
  <refsect1>
diff --git a/doc/src/sgml/ref/create_index.sgml b/doc/src/sgml/ref/create_index.sgml
index 208389e8006..a7693112853 100644
--- a/doc/src/sgml/ref/create_index.sgml
+++ b/doc/src/sgml/ref/create_index.sgml
@@ -28,6 +28,7 @@ CREATE [ UNIQUE ] INDEX [ CONCURRENTLY ] [ [ IF NOT EXISTS ] <replaceable class=
     [ WITH ( <replaceable class="parameter">storage_parameter</replaceable> [= <replaceable class="parameter">value</replaceable>] [, ... ] ) ]
     [ TABLESPACE <replaceable class="parameter">tablespace_name</replaceable> ]
     [ WHERE <replaceable class="parameter">predicate</replaceable> ]
+    [ DISABLE ]
 </synopsis>
  </refsynopsisdiv>
 
@@ -380,6 +381,19 @@ CREATE [ UNIQUE ] INDEX [ CONCURRENTLY ] [ [ IF NOT EXISTS ] <replaceable class=
       </listitem>
      </varlistentry>
 
+    <varlistentry>
+      <term><literal>DISABLE</literal></term>
+      <listitem>
+       <para>
+        Creates the index in a disabled state (default enabled). A disabled index is not used by the
+        query planner for query optimization, but it is still maintained when the
+        underlying table data changes. This can be useful when you want to create
+        an index without immediately impacting query performance, allowing you to
+        enable it later at a more convenient time. The index can be enabled later
+        using <command>ALTER INDEX ... ENABLE</command>.
+       </para>
+      </listitem>
+     </varlistentry>
     </variablelist>
 
   <refsect2 id="sql-createindex-storage-parameters" xreflabel="Index Storage Parameters">
@@ -701,6 +715,14 @@ Indexes:
     partitioned index is a metadata only operation.
    </para>
 
+  <para>
+   When creating an index with the <literal>DISABLE</literal> option, the index
+   will be created but not used for query planning. This can be useful for
+   preparing an index in advance of its use, or for testing purposes. The index
+   will still be maintained as the table is modified, so it can be enabled
+   later without needing to be rebuilt. By default all new indexes are enabled.
+  </para>
+
   </refsect2>
  </refsect1>
 
@@ -980,6 +1002,13 @@ SELECT * FROM points
 CREATE INDEX CONCURRENTLY sales_quantity_index ON sales_table (quantity);
 </programlisting></para>
 
+  <para>
+   To create an index on the table <literal>test_table</literal> with the default
+   name, but have it initially disabled:
+<programlisting>
+CREATE INDEX ON test_table (col1) DISABLE;
+</programlisting>
+  </para>
  </refsect1>
 
  <refsect1>
diff --git a/src/backend/bootstrap/bootparse.y b/src/backend/bootstrap/bootparse.y
index 05ef26c07d0..ba2e7381726 100644
--- a/src/backend/bootstrap/bootparse.y
+++ b/src/backend/bootstrap/bootparse.y
@@ -303,6 +303,7 @@ Boot_DeclareIndexStmt:
 					stmt->concurrent = false;
 					stmt->if_not_exists = false;
 					stmt->reset_default_tblspc = false;
+					stmt->isenabled = true;
 
 					/* locks and races need not concern us in bootstrap mode */
 					relationId = RangeVarGetRelid(stmt->relation, NoLock,
@@ -356,6 +357,7 @@ Boot_DeclareUniqueIndexStmt:
 					stmt->concurrent = false;
 					stmt->if_not_exists = false;
 					stmt->reset_default_tblspc = false;
+					stmt->isenabled = true;
 
 					/* locks and races need not concern us in bootstrap mode */
 					relationId = RangeVarGetRelid(stmt->relation, NoLock,
diff --git a/src/backend/catalog/index.c b/src/backend/catalog/index.c
index 6976249e9e9..e4ab05e902a 100644
--- a/src/backend/catalog/index.c
+++ b/src/backend/catalog/index.c
@@ -118,7 +118,8 @@ static void UpdateIndexRelation(Oid indexoid, Oid heapoid,
 								bool isexclusion,
 								bool immediate,
 								bool isvalid,
-								bool isready);
+								bool isready,
+								bool isenabled);
 static void index_update_stats(Relation rel,
 							   bool hasindex,
 							   double reltuples);
@@ -570,7 +571,8 @@ UpdateIndexRelation(Oid indexoid,
 					bool isexclusion,
 					bool immediate,
 					bool isvalid,
-					bool isready)
+					bool isready,
+					bool isenabled)
 {
 	int2vector *indkey;
 	oidvector  *indcollation;
@@ -648,6 +650,7 @@ UpdateIndexRelation(Oid indexoid,
 	values[Anum_pg_index_indisready - 1] = BoolGetDatum(isready);
 	values[Anum_pg_index_indislive - 1] = BoolGetDatum(true);
 	values[Anum_pg_index_indisreplident - 1] = BoolGetDatum(false);
+	values[Anum_pg_index_indisenabled - 1] = BoolGetDatum(isenabled);
 	values[Anum_pg_index_indkey - 1] = PointerGetDatum(indkey);
 	values[Anum_pg_index_indcollation - 1] = PointerGetDatum(indcollation);
 	values[Anum_pg_index_indclass - 1] = PointerGetDatum(indclass);
@@ -713,6 +716,8 @@ UpdateIndexRelation(Oid indexoid,
  *			already exists.
  *		INDEX_CREATE_PARTITIONED:
  *			create a partitioned index (table must be partitioned)
+ *		INDEX_CREATE_DISABLED:
+*				create the index as disabled if instructed, defaults to being enabled.
  * constr_flags: flags passed to index_constraint_create
  *		(only if INDEX_CREATE_ADD_CONSTRAINT is set)
  * allow_system_table_mods: allow table to be a system catalog
@@ -758,6 +763,7 @@ index_create(Relation heapRelation,
 	bool		invalid = (flags & INDEX_CREATE_INVALID) != 0;
 	bool		concurrent = (flags & INDEX_CREATE_CONCURRENT) != 0;
 	bool		partitioned = (flags & INDEX_CREATE_PARTITIONED) != 0;
+	bool 		isenabled  = (flags & INDEX_CREATE_ENABLED) != 0;
 	char		relkind;
 	TransactionId relfrozenxid;
 	MultiXactId relminmxid;
@@ -1041,13 +1047,15 @@ index_create(Relation heapRelation,
 	 *	  (Or, could define a rule to maintain the predicate) --Nels, Feb '92
 	 * ----------------
 	 */
+
 	UpdateIndexRelation(indexRelationId, heapRelationId, parentIndexRelid,
 						indexInfo,
 						collationIds, opclassIds, coloptions,
 						isprimary, is_exclusion,
 						(constr_flags & INDEX_CONSTR_CREATE_DEFERRABLE) == 0,
 						!concurrent && !invalid,
-						!concurrent);
+						!concurrent,
+						isenabled);
 
 	/*
 	 * Register relcache invalidation on the indexes' heap relation, to
@@ -1316,6 +1324,8 @@ index_concurrently_create_copy(Relation heapRelation, Oid oldIndexId,
 	List	   *indexColNames = NIL;
 	List	   *indexExprs = NIL;
 	List	   *indexPreds = NIL;
+	Form_pg_index indexForm;
+	bits16 	 createFlags;
 
 	indexRelation = index_open(oldIndexId, RowExclusiveLock);
 
@@ -1343,6 +1353,9 @@ index_concurrently_create_copy(Relation heapRelation, Oid oldIndexId,
 											Anum_pg_index_indoption);
 	indcoloptions = (int2vector *) DatumGetPointer(colOptionDatum);
 
+	/* Get the enabled state of the original index */
+	indexForm = (Form_pg_index) GETSTRUCT(indexTuple);
+
 	/* Fetch reloptions of index if any */
 	classTuple = SearchSysCache1(RELOID, ObjectIdGetDatum(oldIndexId));
 	if (!HeapTupleIsValid(classTuple))
@@ -1434,6 +1447,16 @@ index_concurrently_create_copy(Relation heapRelation, Oid oldIndexId,
 		stattargets[i].isnull = isnull;
 	}
 
+	/*
+	* Determine the create flags for the new index.
+	* We always use SKIP_BUILD and CONCURRENT for concurrent reindexing.
+	* If the original index was enabled, we also set the ENABLED flag
+	* to maintain the same state in the new index.
+	*/
+	createFlags = INDEX_CREATE_SKIP_BUILD | INDEX_CREATE_CONCURRENT;
+	if (indexForm->indisenabled)
+			createFlags |= INDEX_CREATE_ENABLED;
+
 	/*
 	 * Now create the new index.
 	 *
@@ -1457,7 +1480,7 @@ index_concurrently_create_copy(Relation heapRelation, Oid oldIndexId,
 							  indcoloptions->values,
 							  stattargets,
 							  reloptionsDatum,
-							  INDEX_CREATE_SKIP_BUILD | INDEX_CREATE_CONCURRENT,
+							  createFlags,
 							  0,
 							  true, /* allow table to be a system catalog? */
 							  false,	/* is_internal? */
diff --git a/src/backend/catalog/toasting.c b/src/backend/catalog/toasting.c
index ad3082c62ac..dead993a742 100644
--- a/src/backend/catalog/toasting.c
+++ b/src/backend/catalog/toasting.c
@@ -325,7 +325,7 @@ create_toast_table(Relation rel, Oid toastOid, Oid toastIndexOid,
 				 BTREE_AM_OID,
 				 rel->rd_rel->reltablespace,
 				 collationIds, opclassIds, NULL, coloptions, NULL, (Datum) 0,
-				 INDEX_CREATE_IS_PRIMARY, 0, true, true, NULL);
+				 INDEX_CREATE_IS_PRIMARY | INDEX_CREATE_ENABLED, 0, true, true, NULL);
 
 	table_close(toast_rel, NoLock);
 
diff --git a/src/backend/commands/indexcmds.c b/src/backend/commands/indexcmds.c
index 4049ce1a10f..b456069f942 100644
--- a/src/backend/commands/indexcmds.c
+++ b/src/backend/commands/indexcmds.c
@@ -1198,6 +1198,10 @@ DefineIndex(Oid tableId,
 		flags |= INDEX_CREATE_PARTITIONED;
 	if (stmt->primary)
 		flags |= INDEX_CREATE_IS_PRIMARY;
+   if (stmt->isenabled)
+		flags |= INDEX_CREATE_ENABLED;
+   else
+		flags &= ~INDEX_CREATE_ENABLED;
 
 	/*
 	 * If the table is partitioned, and recursion was declined but partitions
diff --git a/src/backend/commands/tablecmds.c b/src/backend/commands/tablecmds.c
index 49374782625..7535a4843de 100644
--- a/src/backend/commands/tablecmds.c
+++ b/src/backend/commands/tablecmds.c
@@ -688,7 +688,7 @@ static List *GetParentedForeignKeyRefs(Relation partition);
 static void ATDetachCheckNoForeignKeyRefs(Relation partition);
 static char GetAttributeCompression(Oid atttypid, const char *compression);
 static char GetAttributeStorage(Oid atttypid, const char *storagemode);
-
+static void ATExecEnableDisableIndex(Relation rel, bool enable);
 
 /* ----------------------------------------------------------------
  *		DefineRelation
@@ -4632,6 +4632,8 @@ AlterTableGetLockLevel(List *cmds)
 			case AT_SetExpression:
 			case AT_DropExpression:
 			case AT_SetCompression:
+			case AT_EnableIndex:
+			case AT_DisableIndex:
 				cmd_lockmode = AccessExclusiveLock;
 				break;
 
@@ -5194,6 +5196,12 @@ ATPrepCmd(List **wqueue, Relation rel, AlterTableCmd *cmd,
 			/* No command-specific prep needed */
 			pass = AT_PASS_MISC;
 			break;
+		case AT_EnableIndex:
+		case AT_DisableIndex:
+			ATSimplePermissions(cmd->subtype, rel, ATT_INDEX | ATT_PARTITIONED_INDEX);
+			/* No command-specific prep needed */
+			pass = AT_PASS_MISC;
+			break;
 		default:				/* oops */
 			elog(ERROR, "unrecognized alter table type: %d",
 				 (int) cmd->subtype);
@@ -5588,6 +5596,12 @@ ATExecCmd(List **wqueue, AlteredTableInfo *tab,
 		case AT_DetachPartitionFinalize:
 			address = ATExecDetachPartitionFinalize(rel, ((PartitionCmd *) cmd->def)->name);
 			break;
+		case AT_EnableIndex:
+				ATExecEnableDisableIndex(rel, true);
+				break;
+		case AT_DisableIndex:
+				ATExecEnableDisableIndex(rel, false);
+				break;
 		default:				/* oops */
 			elog(ERROR, "unrecognized alter table type: %d",
 				 (int) cmd->subtype);
@@ -6477,6 +6491,8 @@ alter_table_type_to_string(AlterTableType cmdtype)
 			return "DROP COLUMN";
 		case AT_AddIndex:
 		case AT_ReAddIndex:
+		case AT_EnableIndex:
+		case AT_DisableIndex:
 			return NULL;		/* not real grammar */
 		case AT_AddConstraint:
 		case AT_ReAddConstraint:
@@ -20812,3 +20828,52 @@ GetAttributeStorage(Oid atttypid, const char *storagemode)
 
 	return cstorage;
 }
+
+/*
+ * ATExecEnableDisableIndex
+ * Performs a catalog update to enable or disable an index in pg_index.
+ */
+static void
+ATExecEnableDisableIndex(Relation rel, bool enable)
+{
+	Oid         indexOid = RelationGetRelid(rel);
+	Relation    pg_index;
+	HeapTuple   indexTuple;
+	Form_pg_index indexForm;
+	bool        updated = false;
+
+	pg_index = table_open(IndexRelationId, RowExclusiveLock);
+
+	indexTuple = SearchSysCacheCopy1(INDEXRELID, ObjectIdGetDatum(indexOid));
+	if (!HeapTupleIsValid(indexTuple))
+		elog(ERROR, "could not find tuple for index %u", indexOid);
+
+	indexForm = (Form_pg_index) GETSTRUCT(indexTuple);
+	if (indexForm->indcheckxmin)
+	{
+		heap_freetuple(indexTuple);
+		table_close(pg_index, RowExclusiveLock);
+		ereport(ERROR,
+				(errcode(ERRCODE_OBJECT_NOT_IN_PREREQUISITE_STATE),
+				errmsg("cannot enable/disable index while indcheckxmin is true"),
+				errhint("Wait for all transactions that might see inconsistent HOT chains to complete")));
+	}
+
+	if (indexForm->indisenabled != enable)
+	{
+		indexForm->indisenabled = enable;
+
+		CatalogTupleUpdate(pg_index, &indexTuple->t_self, indexTuple);
+		updated = true;
+	}
+
+	heap_freetuple(indexTuple);
+	table_close(pg_index, RowExclusiveLock);
+
+	if (updated)
+	{
+		CacheInvalidateRelcache(rel);
+		InvokeObjectPostAlterHook(IndexRelationId, indexOid, 0);
+		CommandCounterIncrement();
+	}
+}
diff --git a/src/backend/optimizer/util/plancat.c b/src/backend/optimizer/util/plancat.c
index c31cc3ee69f..79b688fc39c 100644
--- a/src/backend/optimizer/util/plancat.c
+++ b/src/backend/optimizer/util/plancat.c
@@ -295,6 +295,19 @@ get_relation_info(PlannerInfo *root, Oid relationObjectId, bool inhparent,
 			info->opcintype = (Oid *) palloc(sizeof(Oid) * nkeycolumns);
 			info->canreturn = (bool *) palloc(sizeof(bool) * ncolumns);
 
+			/*
+			 * Skip disabled indexes altogether, as they should not be considered
+			 * for query planning. This builds the data structure for the planner's
+			 * use and we make it part of IndexOptInfo since the index is already open.
+			 * We also close the relation before continuing to the next index.
+			 */
+			info->enabled = index->indisenabled;
+			if (!info->enabled)
+			{
+				index_close(indexRelation, NoLock);
+				continue;
+			}
+
 			for (i = 0; i < ncolumns; i++)
 			{
 				info->indexkeys[i] = index->indkey.values[i];
diff --git a/src/backend/parser/gram.y b/src/backend/parser/gram.y
index bd5ebb35c40..64749b9b4f8 100644
--- a/src/backend/parser/gram.y
+++ b/src/backend/parser/gram.y
@@ -320,7 +320,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 %type <ival>	add_drop opt_asc_desc opt_nulls_order
 
 %type <node>	alter_table_cmd alter_type_cmd opt_collate_clause
-	   replica_identity partition_cmd index_partition_cmd
+	   replica_identity partition_cmd index_partition_cmd index_alter_cmd
 %type <list>	alter_table_cmds alter_type_cmds
 %type <list>    alter_identity_column_option_list
 %type <defelt>  alter_identity_column_option
@@ -483,6 +483,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 %type <boolean> opt_unique opt_verbose opt_full
 %type <boolean> opt_freeze opt_analyze opt_default
 %type <defelt>	opt_binary copy_delimiter
+%type <boolean>  opt_index_enabled
 
 %type <boolean> copy_from opt_program
 
@@ -2149,6 +2150,24 @@ AlterTableStmt:
 					n->nowait = $13;
 					$$ = (Node *) n;
 				}
+		| ALTER INDEX qualified_name index_alter_cmd
+				{
+					AlterTableStmt *n = makeNode(AlterTableStmt);
+					n->relation = $3;
+					n->cmds = list_make1($4);
+					n->objtype = OBJECT_INDEX;
+					n->missing_ok = false;
+					$$ = (Node *) n;
+				}
+		| ALTER INDEX IF_P EXISTS qualified_name index_alter_cmd
+				{
+					AlterTableStmt *n = makeNode(AlterTableStmt);
+					n->relation = $5;
+					n->cmds = list_make1($6);
+					n->objtype = OBJECT_INDEX;
+					n->missing_ok = true;
+					$$ = (Node *) n;
+				}
 		|	ALTER INDEX qualified_name alter_table_cmds
 				{
 					AlterTableStmt *n = makeNode(AlterTableStmt);
@@ -2374,6 +2393,21 @@ index_partition_cmd:
 				}
 		;
 
+index_alter_cmd:
+		/* ALTER INDEX <name> ENABLE|DISABLE */
+		ENABLE_P
+			{
+				AlterTableCmd *n = makeNode(AlterTableCmd);
+				n->subtype = AT_EnableIndex;
+				$$ = (Node *) n;
+			}
+		| DISABLE_P
+			{
+				AlterTableCmd *n = makeNode(AlterTableCmd);
+				n->subtype = AT_DisableIndex;
+				$$ = (Node *) n;
+			}
+		;
 alter_table_cmd:
 			/* ALTER TABLE <name> ADD <coldef> */
 			ADD_P columnDef
@@ -8129,7 +8163,7 @@ defacl_privilege_target:
 
 IndexStmt:	CREATE opt_unique INDEX opt_concurrently opt_single_name
 			ON relation_expr access_method_clause '(' index_params ')'
-			opt_include opt_unique_null_treatment opt_reloptions OptTableSpace where_clause
+			opt_include opt_unique_null_treatment opt_reloptions OptTableSpace where_clause opt_index_enabled
 				{
 					IndexStmt *n = makeNode(IndexStmt);
 
@@ -8144,6 +8178,7 @@ IndexStmt:	CREATE opt_unique INDEX opt_concurrently opt_single_name
 					n->options = $14;
 					n->tableSpace = $15;
 					n->whereClause = $16;
+					n->isenabled = $17;
 					n->excludeOpNames = NIL;
 					n->idxcomment = NULL;
 					n->indexOid = InvalidOid;
@@ -8161,7 +8196,7 @@ IndexStmt:	CREATE opt_unique INDEX opt_concurrently opt_single_name
 				}
 			| CREATE opt_unique INDEX opt_concurrently IF_P NOT EXISTS name
 			ON relation_expr access_method_clause '(' index_params ')'
-			opt_include opt_unique_null_treatment opt_reloptions OptTableSpace where_clause
+			opt_include opt_unique_null_treatment opt_reloptions OptTableSpace where_clause opt_index_enabled
 				{
 					IndexStmt *n = makeNode(IndexStmt);
 
@@ -8176,6 +8211,7 @@ IndexStmt:	CREATE opt_unique INDEX opt_concurrently opt_single_name
 					n->options = $17;
 					n->tableSpace = $18;
 					n->whereClause = $19;
+					n->isenabled = $20;
 					n->excludeOpNames = NIL;
 					n->idxcomment = NULL;
 					n->indexOid = InvalidOid;
@@ -8198,6 +8234,12 @@ opt_unique:
 			| /*EMPTY*/								{ $$ = false; }
 		;
 
+opt_index_enabled:
+			ENABLE_P                      { $$ = true; }
+			| DISABLE_P                   { $$ = false; }
+			| /*EMPTY*/                 	{ $$ = true; }
+		;
+
 access_method_clause:
 			USING name								{ $$ = $2; }
 			| /*EMPTY*/								{ $$ = DEFAULT_INDEX_TYPE; }
diff --git a/src/backend/parser/parse_utilcmd.c b/src/backend/parser/parse_utilcmd.c
index 95dad766834..41a8e57f3d3 100644
--- a/src/backend/parser/parse_utilcmd.c
+++ b/src/backend/parser/parse_utilcmd.c
@@ -1736,6 +1736,7 @@ generateClonedIndexStmt(RangeVar *heapRel, Relation source_idx,
 	index->concurrent = false;
 	index->if_not_exists = false;
 	index->reset_default_tblspc = false;
+	index->isenabled = idxrec->indisenabled;
 
 	/*
 	 * We don't try to preserve the name of the source index; instead, just
@@ -2357,6 +2358,8 @@ transformIndexConstraint(Constraint *constraint, CreateStmtContext *cxt)
 	index->concurrent = false;
 	index->if_not_exists = false;
 	index->reset_default_tblspc = constraint->reset_default_tblspc;
+	/* Ensure indexes for constraints are created as enabled by default */
+	index->isenabled = true;
 
 	/*
 	 * If it's ALTER TABLE ADD CONSTRAINT USING INDEX, look up the index and
diff --git a/src/backend/utils/adt/ruleutils.c b/src/backend/utils/adt/ruleutils.c
index be1f1f50b78..2c403a08fe6 100644
--- a/src/backend/utils/adt/ruleutils.c
+++ b/src/backend/utils/adt/ruleutils.c
@@ -1559,6 +1559,10 @@ pg_get_indexdef_worker(Oid indexrelid, int colno,
 			else
 				appendStringInfo(&buf, " WHERE %s", str);
 		}
+
+		/* Add DISABLE clause if the index is disabled */
+		if (!idxrec->indisenabled)
+				appendStringInfoString(&buf, " DISABLE");
 	}
 
 	/* Clean up */
diff --git a/src/backend/utils/cache/relcache.c b/src/backend/utils/cache/relcache.c
index 1ce7eb9da8f..e343c6916fd 100644
--- a/src/backend/utils/cache/relcache.c
+++ b/src/backend/utils/cache/relcache.c
@@ -2311,6 +2311,7 @@ RelationReloadIndexInfo(Relation relation)
 		relation->rd_index->indisready = index->indisready;
 		relation->rd_index->indislive = index->indislive;
 		relation->rd_index->indisreplident = index->indisreplident;
+		relation->rd_index->indisenabled = index->indisenabled;
 
 		/* Copy xmin too, as that is needed to make sense of indcheckxmin */
 		HeapTupleHeaderSetXmin(relation->rd_indextuple->t_data,
diff --git a/src/include/catalog/index.h b/src/include/catalog/index.h
index 2dea96f47c3..8a47cfd174f 100644
--- a/src/include/catalog/index.h
+++ b/src/include/catalog/index.h
@@ -65,6 +65,7 @@ extern void index_check_primary_key(Relation heapRel,
 #define	INDEX_CREATE_IF_NOT_EXISTS			(1 << 4)
 #define	INDEX_CREATE_PARTITIONED			(1 << 5)
 #define INDEX_CREATE_INVALID				(1 << 6)
+#define INDEX_CREATE_ENABLED        (1 << 7)
 
 extern Oid	index_create(Relation heapRelation,
 						 const char *indexRelationName,
@@ -175,7 +176,6 @@ extern void RestoreReindexState(const void *reindexstate);
 
 extern void IndexSetParentIndex(Relation partitionIdx, Oid parentOid);
 
-
 /*
  * itemptr_encode - Encode ItemPointer as int64/int8
  *
diff --git a/src/include/catalog/pg_index.h b/src/include/catalog/pg_index.h
index 6c89639a9e4..b0c7e5f3654 100644
--- a/src/include/catalog/pg_index.h
+++ b/src/include/catalog/pg_index.h
@@ -44,6 +44,7 @@ CATALOG(pg_index,2610,IndexRelationId) BKI_SCHEMA_MACRO
 	bool		indisready;		/* is this index ready for inserts? */
 	bool		indislive;		/* is this index alive at all? */
 	bool		indisreplident; /* is this index the identity for replication? */
+	bool		indisenabled;	/* is this index enabled for use by queries? */
 
 	/* variable-length fields start here, but we allow direct access to indkey */
 	int2vector	indkey BKI_FORCE_NOT_NULL;	/* column numbers of indexed cols,
diff --git a/src/include/nodes/parsenodes.h b/src/include/nodes/parsenodes.h
index 0f9462493e3..5054f9f8bb4 100644
--- a/src/include/nodes/parsenodes.h
+++ b/src/include/nodes/parsenodes.h
@@ -2423,6 +2423,8 @@ typedef enum AlterTableType
 	AT_SetIdentity,				/* SET identity column options */
 	AT_DropIdentity,			/* DROP IDENTITY */
 	AT_ReAddStatistics,			/* internal to commands/tablecmds.c */
+	AT_EnableIndex,					/* ENABLE INDEX */
+	AT_DisableIndex,				/* DISABLE INDEX */
 } AlterTableType;
 
 typedef struct ReplicaIdentityStmt
@@ -3402,6 +3404,7 @@ typedef struct IndexStmt
 	bool		if_not_exists;	/* just do nothing if index already exists? */
 	bool		reset_default_tblspc;	/* reset default_tablespace prior to
 										 * executing */
+  bool		isenabled;		/* true if ENABLE (default), false if DISABLE */
 } IndexStmt;
 
 /* ----------------------
diff --git a/src/include/nodes/pathnodes.h b/src/include/nodes/pathnodes.h
index 58748d2ca6f..be77186c875 100644
--- a/src/include/nodes/pathnodes.h
+++ b/src/include/nodes/pathnodes.h
@@ -1212,6 +1212,8 @@ struct IndexOptInfo
 	/* AM's cost estimator */
 	/* Rather than include amapi.h here, we declare amcostestimate like this */
 	void		(*amcostestimate) (struct PlannerInfo *, struct IndexPath *, double, Cost *, Cost *, Selectivity *, double *, double *) pg_node_attr(read_write_ignore);
+	/* true if this index is enabled */
+	bool		enabled;
 };
 
 /*
diff --git a/src/test/regress/expected/create_index.out b/src/test/regress/expected/create_index.out
index 1904eb65bb9..8e4952ca605 100644
--- a/src/test/regress/expected/create_index.out
+++ b/src/test/regress/expected/create_index.out
@@ -3318,6 +3318,511 @@ ERROR:  REINDEX SCHEMA cannot run inside a transaction block
 END;
 -- concurrently
 REINDEX SCHEMA CONCURRENTLY schema_to_reindex;
+-- Test enable/disable functionality for indexes
+CREATE TABLE index_test(
+    id INT PRIMARY KEY,
+    data TEXT,
+    num INT,
+    vector INT[],
+    range INT4RANGE
+);
+INSERT INTO index_test
+SELECT
+    g,
+    'data ' || g,
+    g % 100,
+    ARRAY[g, g+1, g+2],
+    int4range(g, g+10)
+FROM generate_series(1, 1000) g;
+-- Function for testing
+CREATE FUNCTION get_data_length(text) RETURNS INT AS $$
+    SELECT length($1);
+$$ LANGUAGE SQL IMMUTABLE;
+-- Helper function to show index status
+CREATE OR REPLACE FUNCTION show_index_status(index_name text)
+RETURNS TABLE (
+    indexrelid regclass,
+    indisvalid boolean,
+    indisready boolean,
+    indislive boolean,
+    indisenabled boolean
+) AS $$
+BEGIN
+    RETURN QUERY EXECUTE format('
+        SELECT indexrelid::regclass, indisvalid, indisready, indislive, indisenabled
+        FROM pg_index
+        WHERE indexrelid = %L::regclass', index_name);
+END;
+$$ LANGUAGE plpgsql;
+-- Create and test each index type
+-- 1. Basic single-column index
+CREATE INDEX idx_single ON index_test(data);
+SELECT show_index_status('idx_single');
+  show_index_status   
+----------------------
+ (idx_single,t,t,t,t)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE data = 'data 500';
+                  QUERY PLAN                   
+-----------------------------------------------
+ Bitmap Heap Scan on index_test
+   Recheck Cond: (data = 'data 500'::text)
+   ->  Bitmap Index Scan on idx_single
+         Index Cond: (data = 'data 500'::text)
+(4 rows)
+
+ALTER INDEX idx_single DISABLE;
+SELECT show_index_status('idx_single');
+  show_index_status   
+----------------------
+ (idx_single,t,t,t,f)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE data = 'data 500';
+             QUERY PLAN              
+-------------------------------------
+ Seq Scan on index_test
+   Filter: (data = 'data 500'::text)
+(2 rows)
+
+ALTER INDEX idx_single ENABLE;
+SELECT show_index_status('idx_single');
+  show_index_status   
+----------------------
+ (idx_single,t,t,t,t)
+(1 row)
+
+-- 2. Multi-column index
+CREATE INDEX idx_multi ON index_test(num, data);
+SELECT show_index_status('idx_multi');
+  show_index_status  
+---------------------
+ (idx_multi,t,t,t,t)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE num = 50 AND data > 'data 500';
+                           QUERY PLAN                           
+----------------------------------------------------------------
+ Bitmap Heap Scan on index_test
+   Recheck Cond: ((num = 50) AND (data > 'data 500'::text))
+   ->  Bitmap Index Scan on idx_multi
+         Index Cond: ((num = 50) AND (data > 'data 500'::text))
+(4 rows)
+
+ALTER INDEX idx_multi DISABLE;
+SELECT show_index_status('idx_multi');
+  show_index_status  
+---------------------
+ (idx_multi,t,t,t,f)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE num = 50 AND data > 'data 500';
+                      QUERY PLAN                      
+------------------------------------------------------
+ Seq Scan on index_test
+   Filter: ((data > 'data 500'::text) AND (num = 50))
+(2 rows)
+
+ALTER INDEX idx_multi ENABLE;
+SELECT show_index_status('idx_multi');
+  show_index_status  
+---------------------
+ (idx_multi,t,t,t,t)
+(1 row)
+
+-- 3. Partial index
+CREATE INDEX idx_partial ON index_test(num) WHERE num < 50;
+SELECT show_index_status('idx_partial');
+   show_index_status   
+-----------------------
+ (idx_partial,t,t,t,t)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE num = 25;
+               QUERY PLAN               
+----------------------------------------
+ Bitmap Heap Scan on index_test
+   Recheck Cond: (num = 25)
+   ->  Bitmap Index Scan on idx_partial
+         Index Cond: (num = 25)
+(4 rows)
+
+ALTER INDEX idx_partial DISABLE;
+SELECT show_index_status('idx_partial');
+   show_index_status   
+-----------------------
+ (idx_partial,t,t,t,f)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE num = 25;
+              QUERY PLAN              
+--------------------------------------
+ Bitmap Heap Scan on index_test
+   Recheck Cond: (num = 25)
+   ->  Bitmap Index Scan on idx_multi
+         Index Cond: (num = 25)
+(4 rows)
+
+ALTER INDEX idx_partial ENABLE;
+SELECT show_index_status('idx_partial');
+   show_index_status   
+-----------------------
+ (idx_partial,t,t,t,t)
+(1 row)
+
+-- 4. Expression index
+CREATE INDEX idx_expression ON index_test((lower(data)));
+SELECT show_index_status('idx_expression');
+    show_index_status     
+--------------------------
+ (idx_expression,t,t,t,t)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE lower(data) = 'data 500';
+                      QUERY PLAN                      
+------------------------------------------------------
+ Bitmap Heap Scan on index_test
+   Recheck Cond: (lower(data) = 'data 500'::text)
+   ->  Bitmap Index Scan on idx_expression
+         Index Cond: (lower(data) = 'data 500'::text)
+(4 rows)
+
+ALTER INDEX idx_expression DISABLE;
+SELECT show_index_status('idx_expression');
+    show_index_status     
+--------------------------
+ (idx_expression,t,t,t,f)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE lower(data) = 'data 500';
+                 QUERY PLAN                 
+--------------------------------------------
+ Seq Scan on index_test
+   Filter: (lower(data) = 'data 500'::text)
+(2 rows)
+
+ALTER INDEX idx_expression ENABLE;
+SELECT show_index_status('idx_expression');
+    show_index_status     
+--------------------------
+ (idx_expression,t,t,t,t)
+(1 row)
+
+-- 5. GIN index
+CREATE INDEX idx_gin ON index_test USING gin(vector);
+SELECT show_index_status('idx_gin');
+ show_index_status 
+-------------------
+ (idx_gin,t,t,t,t)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE vector @> ARRAY[500];
+                     QUERY PLAN                     
+----------------------------------------------------
+ Bitmap Heap Scan on index_test
+   Recheck Cond: (vector @> '{500}'::integer[])
+   ->  Bitmap Index Scan on idx_gin
+         Index Cond: (vector @> '{500}'::integer[])
+(4 rows)
+
+ALTER INDEX idx_gin DISABLE;
+SELECT show_index_status('idx_gin');
+ show_index_status 
+-------------------
+ (idx_gin,t,t,t,f)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE vector @> ARRAY[500];
+                QUERY PLAN                
+------------------------------------------
+ Seq Scan on index_test
+   Filter: (vector @> '{500}'::integer[])
+(2 rows)
+
+ALTER INDEX idx_gin ENABLE;
+SELECT show_index_status('idx_gin');
+ show_index_status 
+-------------------
+ (idx_gin,t,t,t,t)
+(1 row)
+
+-- 6. GiST index
+CREATE INDEX idx_gist ON index_test USING gist(range);
+SELECT show_index_status('idx_gist');
+ show_index_status  
+--------------------
+ (idx_gist,t,t,t,t)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE range && int4range(100, 110);
+                      QUERY PLAN                       
+-------------------------------------------------------
+ Bitmap Heap Scan on index_test
+   Recheck Cond: (range && '[100,110)'::int4range)
+   ->  Bitmap Index Scan on idx_gist
+         Index Cond: (range && '[100,110)'::int4range)
+(4 rows)
+
+ALTER INDEX idx_gist DISABLE;
+SELECT show_index_status('idx_gist');
+ show_index_status  
+--------------------
+ (idx_gist,t,t,t,f)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE range && int4range(100, 110);
+                 QUERY PLAN                  
+---------------------------------------------
+ Seq Scan on index_test
+   Filter: (range && '[100,110)'::int4range)
+(2 rows)
+
+ALTER INDEX idx_gist ENABLE;
+SELECT show_index_status('idx_gist');
+ show_index_status  
+--------------------
+ (idx_gist,t,t,t,t)
+(1 row)
+
+-- 7. Covering index
+CREATE INDEX idx_covering ON index_test(num) INCLUDE (data);
+SELECT show_index_status('idx_covering');
+   show_index_status    
+------------------------
+ (idx_covering,t,t,t,t)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT num, data FROM index_test WHERE num = 50;
+               QUERY PLAN                
+-----------------------------------------
+ Bitmap Heap Scan on index_test
+   Recheck Cond: (num = 50)
+   ->  Bitmap Index Scan on idx_covering
+         Index Cond: (num = 50)
+(4 rows)
+
+ALTER INDEX idx_covering DISABLE;
+SELECT show_index_status('idx_covering');
+   show_index_status    
+------------------------
+ (idx_covering,t,t,t,f)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT num, data FROM index_test WHERE num = 50;
+              QUERY PLAN              
+--------------------------------------
+ Bitmap Heap Scan on index_test
+   Recheck Cond: (num = 50)
+   ->  Bitmap Index Scan on idx_multi
+         Index Cond: (num = 50)
+(4 rows)
+
+ALTER INDEX idx_covering ENABLE;
+SELECT show_index_status('idx_covering');
+   show_index_status    
+------------------------
+ (idx_covering,t,t,t,t)
+(1 row)
+
+-- 8. Unique index
+CREATE UNIQUE INDEX idx_unique ON index_test(id, data);
+SELECT show_index_status('idx_unique');
+  show_index_status   
+----------------------
+ (idx_unique,t,t,t,t)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE id = 500 AND data = 'data 500';
+                        QUERY PLAN                        
+----------------------------------------------------------
+ Index Scan using idx_unique on index_test
+   Index Cond: ((id = 500) AND (data = 'data 500'::text))
+(2 rows)
+
+ALTER INDEX idx_unique DISABLE;
+SELECT show_index_status('idx_unique');
+  show_index_status   
+----------------------
+ (idx_unique,t,t,t,f)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE id = 500 AND data = 'data 500';
+                   QUERY PLAN                   
+------------------------------------------------
+ Index Scan using index_test_pkey on index_test
+   Index Cond: (id = 500)
+   Filter: (data = 'data 500'::text)
+(3 rows)
+
+ALTER INDEX idx_unique ENABLE;
+SELECT show_index_status('idx_unique');
+  show_index_status   
+----------------------
+ (idx_unique,t,t,t,t)
+(1 row)
+
+-- 9. Function-based index
+CREATE INDEX idx_func ON index_test(get_data_length(data));
+SELECT show_index_status('idx_func');
+ show_index_status  
+--------------------
+ (idx_func,t,t,t,t)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE get_data_length(data) = 10;
+               QUERY PLAN                
+-----------------------------------------
+ Bitmap Heap Scan on index_test
+   Recheck Cond: (length(data) = 10)
+   ->  Bitmap Index Scan on idx_func
+         Index Cond: (length(data) = 10)
+(4 rows)
+
+ALTER INDEX idx_func DISABLE;
+SELECT show_index_status('idx_func');
+ show_index_status  
+--------------------
+ (idx_func,t,t,t,f)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE get_data_length(data) = 10;
+          QUERY PLAN           
+-------------------------------
+ Seq Scan on index_test
+   Filter: (length(data) = 10)
+(2 rows)
+
+ALTER INDEX idx_func ENABLE;
+SELECT show_index_status('idx_func');
+ show_index_status  
+--------------------
+ (idx_func,t,t,t,t)
+(1 row)
+
+-- 10. Join index
+CREATE TABLE join_test (id INT PRIMARY KEY, ref_id INT);
+INSERT INTO join_test SELECT g, g % 100 FROM generate_series(1, 1000) g;
+CREATE INDEX idx_join ON join_test(ref_id);
+SELECT show_index_status('idx_join');
+ show_index_status  
+--------------------
+ (idx_join,t,t,t,t)
+(1 row)
+
+EXPLAIN (COSTS OFF)
+SELECT jt.id, it.data
+FROM join_test jt
+JOIN index_test it ON jt.ref_id = it.num
+WHERE jt.id BETWEEN 100 AND 200;
+                          QUERY PLAN                           
+---------------------------------------------------------------
+ Hash Join
+   Hash Cond: (it.num = jt.ref_id)
+   ->  Seq Scan on index_test it
+   ->  Hash
+         ->  Bitmap Heap Scan on join_test jt
+               Recheck Cond: ((id >= 100) AND (id <= 200))
+               ->  Bitmap Index Scan on join_test_pkey
+                     Index Cond: ((id >= 100) AND (id <= 200))
+(8 rows)
+
+-- Disable all indexes to force seq scan
+ALTER INDEX idx_join DISABLE;
+ALTER INDEX join_test_pkey DISABLE;
+SELECT show_index_status('idx_join');
+ show_index_status  
+--------------------
+ (idx_join,t,t,t,f)
+(1 row)
+
+SELECT show_index_status('join_test_pkey');
+    show_index_status     
+--------------------------
+ (join_test_pkey,t,t,t,f)
+(1 row)
+
+EXPLAIN (COSTS OFF)
+SELECT jt.id, it.data
+FROM join_test jt
+JOIN index_test it ON jt.ref_id = it.num
+WHERE jt.id BETWEEN 100 AND 200;
+                     QUERY PLAN                      
+-----------------------------------------------------
+ Hash Join
+   Hash Cond: (it.num = jt.ref_id)
+   ->  Seq Scan on index_test it
+   ->  Hash
+         ->  Seq Scan on join_test jt
+               Filter: ((id >= 100) AND (id <= 200))
+(6 rows)
+
+ALTER INDEX idx_join ENABLE;
+ALTER INDEX join_test_pkey ENABLE;
+SELECT show_index_status('idx_join');
+ show_index_status  
+--------------------
+ (idx_join,t,t,t,t)
+(1 row)
+
+SELECT show_index_status('join_test_pkey');
+    show_index_status     
+--------------------------
+ (join_test_pkey,t,t,t,t)
+(1 row)
+
+-- Test REINDEX CONCURRENTLY
+REINDEX INDEX CONCURRENTLY idx_join;
+SELECT show_index_status('idx_join');
+ show_index_status  
+--------------------
+ (idx_join,t,t,t,t)
+(1 row)
+
+ALTER INDEX idx_join DISABLE;
+SELECT show_index_status('idx_join');
+ show_index_status  
+--------------------
+ (idx_join,t,t,t,f)
+(1 row)
+
+REINDEX INDEX CONCURRENTLY idx_join;
+SELECT show_index_status('idx_join');
+ show_index_status  
+--------------------
+ (idx_join,t,t,t,f)
+(1 row)
+
+SELECT pg_get_indexdef('idx_join'::regclass);
+                                  pg_get_indexdef                                  
+-----------------------------------------------------------------------------------
+ CREATE INDEX idx_join ON schema_to_reindex.join_test USING btree (ref_id) DISABLE
+(1 row)
+
+ALTER INDEX idx_join ENABLE;
+SELECT pg_get_indexdef('idx_join'::regclass);
+                              pg_get_indexdef                              
+---------------------------------------------------------------------------
+ CREATE INDEX idx_join ON schema_to_reindex.join_test USING btree (ref_id)
+(1 row)
+
+-- Test enable/disable index with indcheckxmin being true
+CREATE TABLE indcheckxmin_test(id int PRIMARY KEY);
+INSERT INTO indcheckxmin_test VALUES (1), (2), (3);
+CREATE INDEX CONCURRENTLY idx_checkxmin ON indcheckxmin_test(id);
+BEGIN;
+-- Simulate indcheckxmin being true
+UPDATE pg_index SET indcheckxmin = true WHERE indexrelid = 'idx_checkxmin'::regclass;
+ALTER INDEX idx_checkxmin DISABLE;  -- expect fail
+ERROR:  cannot enable/disable index while indcheckxmin is true
+HINT:  Wait for all transactions that might see inconsistent HOT chains to complete
+ROLLBACK;
+-- Clean up
+DROP TABLE index_test;
+DROP TABLE join_test;
+DROP FUNCTION get_data_length;
+DROP FUNCTION show_index_status;
+DROP TABLE indcheckxmin_test CASCADE;
 -- Failure for unauthorized user
 CREATE ROLE regress_reindexuser NOLOGIN;
 SET SESSION ROLE regress_reindexuser;
diff --git a/src/test/regress/sql/create_index.sql b/src/test/regress/sql/create_index.sql
index c085e05f052..2d61ff2f9bb 100644
--- a/src/test/regress/sql/create_index.sql
+++ b/src/test/regress/sql/create_index.sql
@@ -1410,6 +1410,198 @@ END;
 -- concurrently
 REINDEX SCHEMA CONCURRENTLY schema_to_reindex;
 
+-- Test enable/disable functionality for indexes
+
+CREATE TABLE index_test(
+    id INT PRIMARY KEY,
+    data TEXT,
+    num INT,
+    vector INT[],
+    range INT4RANGE
+);
+
+INSERT INTO index_test
+SELECT
+    g,
+    'data ' || g,
+    g % 100,
+    ARRAY[g, g+1, g+2],
+    int4range(g, g+10)
+FROM generate_series(1, 1000) g;
+
+-- Function for testing
+CREATE FUNCTION get_data_length(text) RETURNS INT AS $$
+    SELECT length($1);
+$$ LANGUAGE SQL IMMUTABLE;
+
+-- Helper function to show index status
+CREATE OR REPLACE FUNCTION show_index_status(index_name text)
+RETURNS TABLE (
+    indexrelid regclass,
+    indisvalid boolean,
+    indisready boolean,
+    indislive boolean,
+    indisenabled boolean
+) AS $$
+BEGIN
+    RETURN QUERY EXECUTE format('
+        SELECT indexrelid::regclass, indisvalid, indisready, indislive, indisenabled
+        FROM pg_index
+        WHERE indexrelid = %L::regclass', index_name);
+END;
+$$ LANGUAGE plpgsql;
+
+-- Create and test each index type
+-- 1. Basic single-column index
+CREATE INDEX idx_single ON index_test(data);
+SELECT show_index_status('idx_single');
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE data = 'data 500';
+ALTER INDEX idx_single DISABLE;
+SELECT show_index_status('idx_single');
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE data = 'data 500';
+ALTER INDEX idx_single ENABLE;
+SELECT show_index_status('idx_single');
+
+-- 2. Multi-column index
+CREATE INDEX idx_multi ON index_test(num, data);
+SELECT show_index_status('idx_multi');
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE num = 50 AND data > 'data 500';
+ALTER INDEX idx_multi DISABLE;
+SELECT show_index_status('idx_multi');
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE num = 50 AND data > 'data 500';
+ALTER INDEX idx_multi ENABLE;
+SELECT show_index_status('idx_multi');
+
+-- 3. Partial index
+CREATE INDEX idx_partial ON index_test(num) WHERE num < 50;
+SELECT show_index_status('idx_partial');
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE num = 25;
+ALTER INDEX idx_partial DISABLE;
+SELECT show_index_status('idx_partial');
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE num = 25;
+ALTER INDEX idx_partial ENABLE;
+SELECT show_index_status('idx_partial');
+
+-- 4. Expression index
+CREATE INDEX idx_expression ON index_test((lower(data)));
+SELECT show_index_status('idx_expression');
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE lower(data) = 'data 500';
+ALTER INDEX idx_expression DISABLE;
+SELECT show_index_status('idx_expression');
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE lower(data) = 'data 500';
+ALTER INDEX idx_expression ENABLE;
+SELECT show_index_status('idx_expression');
+
+-- 5. GIN index
+CREATE INDEX idx_gin ON index_test USING gin(vector);
+SELECT show_index_status('idx_gin');
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE vector @> ARRAY[500];
+ALTER INDEX idx_gin DISABLE;
+SELECT show_index_status('idx_gin');
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE vector @> ARRAY[500];
+ALTER INDEX idx_gin ENABLE;
+SELECT show_index_status('idx_gin');
+
+-- 6. GiST index
+CREATE INDEX idx_gist ON index_test USING gist(range);
+SELECT show_index_status('idx_gist');
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE range && int4range(100, 110);
+ALTER INDEX idx_gist DISABLE;
+SELECT show_index_status('idx_gist');
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE range && int4range(100, 110);
+ALTER INDEX idx_gist ENABLE;
+SELECT show_index_status('idx_gist');
+
+-- 7. Covering index
+CREATE INDEX idx_covering ON index_test(num) INCLUDE (data);
+SELECT show_index_status('idx_covering');
+EXPLAIN (COSTS OFF) SELECT num, data FROM index_test WHERE num = 50;
+ALTER INDEX idx_covering DISABLE;
+SELECT show_index_status('idx_covering');
+EXPLAIN (COSTS OFF) SELECT num, data FROM index_test WHERE num = 50;
+ALTER INDEX idx_covering ENABLE;
+SELECT show_index_status('idx_covering');
+
+-- 8. Unique index
+CREATE UNIQUE INDEX idx_unique ON index_test(id, data);
+SELECT show_index_status('idx_unique');
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE id = 500 AND data = 'data 500';
+ALTER INDEX idx_unique DISABLE;
+SELECT show_index_status('idx_unique');
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE id = 500 AND data = 'data 500';
+ALTER INDEX idx_unique ENABLE;
+SELECT show_index_status('idx_unique');
+
+-- 9. Function-based index
+CREATE INDEX idx_func ON index_test(get_data_length(data));
+SELECT show_index_status('idx_func');
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE get_data_length(data) = 10;
+ALTER INDEX idx_func DISABLE;
+SELECT show_index_status('idx_func');
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE get_data_length(data) = 10;
+ALTER INDEX idx_func ENABLE;
+SELECT show_index_status('idx_func');
+
+-- 10. Join index
+CREATE TABLE join_test (id INT PRIMARY KEY, ref_id INT);
+INSERT INTO join_test SELECT g, g % 100 FROM generate_series(1, 1000) g;
+CREATE INDEX idx_join ON join_test(ref_id);
+SELECT show_index_status('idx_join');
+
+EXPLAIN (COSTS OFF)
+SELECT jt.id, it.data
+FROM join_test jt
+JOIN index_test it ON jt.ref_id = it.num
+WHERE jt.id BETWEEN 100 AND 200;
+
+-- Disable all indexes to force seq scan
+ALTER INDEX idx_join DISABLE;
+ALTER INDEX join_test_pkey DISABLE;
+SELECT show_index_status('idx_join');
+SELECT show_index_status('join_test_pkey');
+
+EXPLAIN (COSTS OFF)
+SELECT jt.id, it.data
+FROM join_test jt
+JOIN index_test it ON jt.ref_id = it.num
+WHERE jt.id BETWEEN 100 AND 200;
+
+ALTER INDEX idx_join ENABLE;
+ALTER INDEX join_test_pkey ENABLE;
+SELECT show_index_status('idx_join');
+SELECT show_index_status('join_test_pkey');
+
+-- Test REINDEX CONCURRENTLY
+REINDEX INDEX CONCURRENTLY idx_join;
+SELECT show_index_status('idx_join');
+
+ALTER INDEX idx_join DISABLE;
+SELECT show_index_status('idx_join');
+REINDEX INDEX CONCURRENTLY idx_join;
+SELECT show_index_status('idx_join');
+
+SELECT pg_get_indexdef('idx_join'::regclass);
+ALTER INDEX idx_join ENABLE;
+SELECT pg_get_indexdef('idx_join'::regclass);
+
+-- Test enable/disable index with indcheckxmin being true
+
+CREATE TABLE indcheckxmin_test(id int PRIMARY KEY);
+INSERT INTO indcheckxmin_test VALUES (1), (2), (3);
+CREATE INDEX CONCURRENTLY idx_checkxmin ON indcheckxmin_test(id);
+BEGIN;
+-- Simulate indcheckxmin being true
+UPDATE pg_index SET indcheckxmin = true WHERE indexrelid = 'idx_checkxmin'::regclass;
+ALTER INDEX idx_checkxmin DISABLE;  -- expect fail
+ROLLBACK;
+
+-- Clean up
+DROP TABLE index_test;
+DROP TABLE join_test;
+DROP FUNCTION get_data_length;
+DROP FUNCTION show_index_status;
+DROP TABLE indcheckxmin_test CASCADE;
+
 -- Failure for unauthorized user
 CREATE ROLE regress_reindexuser NOLOGIN;
 SET SESSION ROLE regress_reindexuser;
-- 
2.39.5 (Apple Git-154)

#49Michail Nikolaev
michail.nikolaev@gmail.com
In reply to: Shayon Mukherjee (#48)
Re: Proposal to Enable/Disable Index using ALTER INDEX (with patch)

Hello.

A few comments on patch:

+ temporarily reducing the overhead of index maintenance
+      during bulk data loading operations

But tuples are still inserted, where the difference come from?

or verifying an index is not being used
+ before dropping it

Hm, it does not provide the guarantee - index may also be used as an
arbiter for INSERT ON CONFLICT, for example. For that case, "update
pg_index set indisvalid = false" should be used before the DROP, probably.
Also index may also be used for constraint, part of partitioned table, etc.

Also, I think it is better to move check to indisvalid as if
(!index->indisvalid || !index->indisenabled).

Best regards,
Mikhail.

#50Shayon Mukherjee
shayonj@gmail.com
In reply to: Michail Nikolaev (#49)
1 attachment(s)
Re: Proposal to Enable/Disable Index using ALTER INDEX (with patch)

On Mon, Dec 30, 2024 at 11:08 AM Michail Nikolaev <
michail.nikolaev@gmail.com> wrote:

Hello.

A few comments on patch:

Thank you for the feedback.

+ temporarily reducing the overhead of index maintenance
+      during bulk data loading operations

But tuples are still inserted, where the difference come from?

I think in retrospect this wasn't needed. I likely conflated a few
different use cases of this feature in the docs and I can see how it may
get confusing. I was originally thinking of the scenario where the use case
of this feature could allow users to identify indexes no longer needed and
once dropped, it would simplify the above tasks. I have simplified
the documentation now and removed that reference.

or verifying an index is not being used
+ before dropping it

Hm, it does not provide the guarantee - index may also be used as an
arbiter for INSERT ON CONFLICT, for example. For that case, "update
pg_index set indisvalid = false" should be used before the DROP, probably.
Also index may also be used for constraint, part of partitioned table, etc.

Good catch, thank you! The feature is primarily geared towards the query
planner, so we are intentionally not changing the enforcements of say
constraints, including uniqueness, and the ones you mentioned above. I have
updated the documentation to call out the distinction. Let me know if you
think we can tweak the wording further.

Also, I think it is better to move check to indisvalid as if
(!index->indisvalid || !index->indisenabled).

Thank you! I was a bit split in terms of code maintenance and quality, so
originally I went with a dedicated block and a return/continue statement
for index ->indisenabled . I have now updated the patch to perform if
(!index->indisvalid || !index->indisenabled) and also updated the code
comment accordingly.

Rebased with the latest master as well.

Thank you
Shayon

Attachments:

v6-0001-Introduce-the-ability-to-enable-disable-indexes-u.patchapplication/octet-stream; name=v6-0001-Introduce-the-ability-to-enable-disable-indexes-u.patchDownload
From c7648b7c21d3433e30680ad614940367c6306342 Mon Sep 17 00:00:00 2001
From: Shayon Mukherjee <shayonj@gmail.com>
Date: Thu, 17 Oct 2024 10:04:13 -0400
Subject: [PATCH v6] Introduce the ability to enable/disable indexes using
 ALTER INDEX

This patch introduces the ability to enable or disable indexes using ALTER INDEX
and CREATE INDEX commands.

Original motivation for the problem and proposal for a patch
can be found at [1].

This patch passes all the existing specs and the newly added regression tests. The patch
is ready for review and test. It compiles, so the can patch can be applied for testing as well.

Implementation details:

- New Grammar:
  * ALTER INDEX ... ENABLE/DISABLE
  * CREATE INDEX ... DISABLE

- Default state is enabled. Indexes are only disabled when explicitly
  instructed via CREATE INDEX ... DISABLE or ALTER INDEX ... DISABLE.

- Primary Key and Unique constraint indexes are always enabled as well. The
  ENABLE/DISABLE grammar is not supported for these types of indexes. They can
  be later disabled via ALTER INDEX ... ENABLE/DISABLE.

- ALTER INDEX ... ENABLE/DISABLE performs update on the relevant row in pg_index
  catalog

- pg_get_indexdef() support the new functionality and grammar. This change is
  reflected in \d output for tables and pg_dump. We show the DISABLE syntax accordingly.

- Updated create_index.sql regression test to cover the new grammar and verify
  that disabled indexes are not used in queries. The test CATALOG_VERSION_NO

  - Basic single-column and multi-column indexes
  - Partial indexes
  - Expression indexes
  - Join indexes
  - GIN and GiST indexes
  - Covering indexes
  - Range indexes
  - Unique indexes and constraints

- Adds a new enabled attribute to the IndexOptInfo structure.

- Modifies get_relation_info in plancat.c to skip disabled indexes entirely, thus reducing the number of places we need to check if an index is disabled or not. Inspired by the conversations start at [2].
  - I chose to modify the logic within get_relation_info as compared to, say, reducing the cost to make the planner not consider an index during planning, mostly to keep the number of changes being introduced to a minimum and also the logic itself being self-contained and easier to under perhaps (?).

- No changes are made to stop the index from getting rebuilt. This way we ensure no
  data miss or corruption when index is re-nabled.

- TOAST indexes are supported and enabled by default as well.

- REINDEX CONCURRENTLY is supported as well and existing state of pg_index.indisenabled
  is carried over accordingly.

- See the changes in create_index.sql to get an idea of the grammar and sql statements.

- See the changes in create_index.out to get an idea of the catalogue states and EXPLAIN
  output to see when an index is getting used or isn't (when disabled).

- Incorporated DavidR's feedback from [3] around documentation and also you will see that by skip disabled indexes entirely from get_relation_info in plancat.c (as mentioned above), we address the other mentioned issues as well.

- Lastly, protects against the case where indcheckxmin is true by raising ERRCODE_OBJECT_NOT_IN_PREREQUISITE_STATE.

Looking forward to any and all feedback on this patch, including but not limited to code quality, tests, fundamental logic.

[1] https://www.postgresql.org/message-id/CANqtF-oXKe0M%3D0QOih6H%2BsZRjE2BWAbkW_1%2B9nMEAMLxUJg5jA%40mail.gmail.com
[2] https://www.postgresql.org/message-id/3465209.1727202064%40sss.pgh.pa.us
[3] https://www.postgresql.org/message-id/CAApHDvpUNu%3DiVcdJ74sypvgeaCF%2Btfpyb8VRhZaF7DTd1xVr7g%40mail.gmail.com
---
 doc/src/sgml/catalogs.sgml                 |  11 +
 doc/src/sgml/ref/alter_index.sgml          |  46 ++
 doc/src/sgml/ref/create_index.sgml         |  29 ++
 src/backend/bootstrap/bootparse.y          |   2 +
 src/backend/catalog/index.c                |  31 +-
 src/backend/catalog/toasting.c             |   2 +-
 src/backend/commands/indexcmds.c           |   4 +
 src/backend/commands/tablecmds.c           |  67 ++-
 src/backend/optimizer/util/plancat.c       |  11 +-
 src/backend/parser/gram.y                  |  48 +-
 src/backend/parser/parse_utilcmd.c         |   3 +
 src/backend/utils/adt/ruleutils.c          |   4 +
 src/backend/utils/cache/relcache.c         |   1 +
 src/include/catalog/index.h                |   2 +-
 src/include/catalog/pg_index.h             |   1 +
 src/include/nodes/parsenodes.h             |   3 +
 src/include/nodes/pathnodes.h              |   2 +
 src/test/regress/expected/create_index.out | 505 +++++++++++++++++++++
 src/test/regress/sql/create_index.sql      | 192 ++++++++
 19 files changed, 948 insertions(+), 16 deletions(-)

diff --git a/doc/src/sgml/catalogs.sgml b/doc/src/sgml/catalogs.sgml
index cc6cf9bef0..f49ef308ab 100644
--- a/doc/src/sgml/catalogs.sgml
+++ b/doc/src/sgml/catalogs.sgml
@@ -4585,6 +4585,17 @@ SCRAM-SHA-256$<replaceable>&lt;iteration count&gt;</replaceable>:<replaceable>&l
        partial index.
       </para></entry>
      </row>
+
+     <row>
+      <entry role="catalog_table_entry"><para role="column_definition">
+       <structfield>indisenabled</structfield> <type>bool</type>
+      </para>
+      <para>
+       If true, the index is currently enabled and should be used for queries.
+       If false, the index is disabled and should not be used for queries,
+       but is still maintained when the table is modified. Default is true.
+      </para></entry>
+     </row>
     </tbody>
    </tgroup>
   </table>
diff --git a/doc/src/sgml/ref/alter_index.sgml b/doc/src/sgml/ref/alter_index.sgml
index 1d42d05d85..2f4cbf155e 100644
--- a/doc/src/sgml/ref/alter_index.sgml
+++ b/doc/src/sgml/ref/alter_index.sgml
@@ -31,6 +31,8 @@ ALTER INDEX [ IF EXISTS ] <replaceable class="parameter">name</replaceable> ALTE
     SET STATISTICS <replaceable class="parameter">integer</replaceable>
 ALTER INDEX ALL IN TABLESPACE <replaceable class="parameter">name</replaceable> [ OWNED BY <replaceable class="parameter">role_name</replaceable> [, ... ] ]
     SET TABLESPACE <replaceable class="parameter">new_tablespace</replaceable> [ NOWAIT ]
+ALTER INDEX [ IF EXISTS ] <replaceable class="parameter">name</replaceable> ENABLE
+ALTER INDEX [ IF EXISTS ] <replaceable class="parameter">name</replaceable> DISABLE
 </synopsis>
  </refsynopsisdiv>
 
@@ -159,6 +161,36 @@ ALTER INDEX ALL IN TABLESPACE <replaceable class="parameter">name</replaceable>
     </listitem>
    </varlistentry>
 
+   <varlistentry>
+    <term><literal>ENABLE</literal></term>
+    <listitem>
+     <para>
+      Enable the specified index. The index will be used by the query planner
+      for query optimization. This is the default state for newly created indexes.
+     </para>
+    </listitem>
+   </varlistentry>
+
+   <varlistentry>
+    <term><literal>DISABLE</literal></term>
+    <listitem>
+     <para>
+      Disable the specified index. A disabled index is not used by the query planner
+      for query optimization, but it is still maintained when the underlying table
+      data changes and will still be used to enforce constraints (such as UNIQUE,
+      or PRIMARY KEY constraints). This can be useful for testing query
+      performance with and without specific indexes. If performance degrades after
+      disabling an index, it can be easily re-enabled using <literal>ENABLE</literal>.
+      Before disabling, it's recommended to check
+      <structname>pg_stat_user_indexes</structname>.<structfield>idx_scan</structfield>
+      to identify potentially unused indexes. Note that if you want to completely
+      prevent an index from being used, including for constraint enforcement, you
+      would need to mark it as invalid using a direct update to the system catalogs
+      (e.g., <literal>UPDATE pg_index SET indisvalid = false WHERE indexrelid = 'index_name'::regclass</literal>).
+     </para>
+    </listitem>
+   </varlistentry>
+
   </variablelist>
   </para>
 
@@ -301,6 +333,20 @@ CREATE INDEX coord_idx ON measured (x, y, (z + t));
 ALTER INDEX coord_idx ALTER COLUMN 3 SET STATISTICS 1000;
 </programlisting></para>
 
+  <para>
+   To enable an index:
+<programlisting>
+ALTER INDEX idx_name ENABLE;
+</programlisting>
+  </para>
+
+  <para>
+   To disable an index:
+<programlisting>
+ALTER INDEX idx_name DISABLE;
+</programlisting>
+  </para>
+
  </refsect1>
 
  <refsect1>
diff --git a/doc/src/sgml/ref/create_index.sgml b/doc/src/sgml/ref/create_index.sgml
index 208389e800..a769311285 100644
--- a/doc/src/sgml/ref/create_index.sgml
+++ b/doc/src/sgml/ref/create_index.sgml
@@ -28,6 +28,7 @@ CREATE [ UNIQUE ] INDEX [ CONCURRENTLY ] [ [ IF NOT EXISTS ] <replaceable class=
     [ WITH ( <replaceable class="parameter">storage_parameter</replaceable> [= <replaceable class="parameter">value</replaceable>] [, ... ] ) ]
     [ TABLESPACE <replaceable class="parameter">tablespace_name</replaceable> ]
     [ WHERE <replaceable class="parameter">predicate</replaceable> ]
+    [ DISABLE ]
 </synopsis>
  </refsynopsisdiv>
 
@@ -380,6 +381,19 @@ CREATE [ UNIQUE ] INDEX [ CONCURRENTLY ] [ [ IF NOT EXISTS ] <replaceable class=
       </listitem>
      </varlistentry>
 
+    <varlistentry>
+      <term><literal>DISABLE</literal></term>
+      <listitem>
+       <para>
+        Creates the index in a disabled state (default enabled). A disabled index is not used by the
+        query planner for query optimization, but it is still maintained when the
+        underlying table data changes. This can be useful when you want to create
+        an index without immediately impacting query performance, allowing you to
+        enable it later at a more convenient time. The index can be enabled later
+        using <command>ALTER INDEX ... ENABLE</command>.
+       </para>
+      </listitem>
+     </varlistentry>
     </variablelist>
 
   <refsect2 id="sql-createindex-storage-parameters" xreflabel="Index Storage Parameters">
@@ -701,6 +715,14 @@ Indexes:
     partitioned index is a metadata only operation.
    </para>
 
+  <para>
+   When creating an index with the <literal>DISABLE</literal> option, the index
+   will be created but not used for query planning. This can be useful for
+   preparing an index in advance of its use, or for testing purposes. The index
+   will still be maintained as the table is modified, so it can be enabled
+   later without needing to be rebuilt. By default all new indexes are enabled.
+  </para>
+
   </refsect2>
  </refsect1>
 
@@ -980,6 +1002,13 @@ SELECT * FROM points
 CREATE INDEX CONCURRENTLY sales_quantity_index ON sales_table (quantity);
 </programlisting></para>
 
+  <para>
+   To create an index on the table <literal>test_table</literal> with the default
+   name, but have it initially disabled:
+<programlisting>
+CREATE INDEX ON test_table (col1) DISABLE;
+</programlisting>
+  </para>
  </refsect1>
 
  <refsect1>
diff --git a/src/backend/bootstrap/bootparse.y b/src/backend/bootstrap/bootparse.y
index 05ef26c07d..ba2e738172 100644
--- a/src/backend/bootstrap/bootparse.y
+++ b/src/backend/bootstrap/bootparse.y
@@ -303,6 +303,7 @@ Boot_DeclareIndexStmt:
 					stmt->concurrent = false;
 					stmt->if_not_exists = false;
 					stmt->reset_default_tblspc = false;
+					stmt->isenabled = true;
 
 					/* locks and races need not concern us in bootstrap mode */
 					relationId = RangeVarGetRelid(stmt->relation, NoLock,
@@ -356,6 +357,7 @@ Boot_DeclareUniqueIndexStmt:
 					stmt->concurrent = false;
 					stmt->if_not_exists = false;
 					stmt->reset_default_tblspc = false;
+					stmt->isenabled = true;
 
 					/* locks and races need not concern us in bootstrap mode */
 					relationId = RangeVarGetRelid(stmt->relation, NoLock,
diff --git a/src/backend/catalog/index.c b/src/backend/catalog/index.c
index 6976249e9e..e4ab05e902 100644
--- a/src/backend/catalog/index.c
+++ b/src/backend/catalog/index.c
@@ -118,7 +118,8 @@ static void UpdateIndexRelation(Oid indexoid, Oid heapoid,
 								bool isexclusion,
 								bool immediate,
 								bool isvalid,
-								bool isready);
+								bool isready,
+								bool isenabled);
 static void index_update_stats(Relation rel,
 							   bool hasindex,
 							   double reltuples);
@@ -570,7 +571,8 @@ UpdateIndexRelation(Oid indexoid,
 					bool isexclusion,
 					bool immediate,
 					bool isvalid,
-					bool isready)
+					bool isready,
+					bool isenabled)
 {
 	int2vector *indkey;
 	oidvector  *indcollation;
@@ -648,6 +650,7 @@ UpdateIndexRelation(Oid indexoid,
 	values[Anum_pg_index_indisready - 1] = BoolGetDatum(isready);
 	values[Anum_pg_index_indislive - 1] = BoolGetDatum(true);
 	values[Anum_pg_index_indisreplident - 1] = BoolGetDatum(false);
+	values[Anum_pg_index_indisenabled - 1] = BoolGetDatum(isenabled);
 	values[Anum_pg_index_indkey - 1] = PointerGetDatum(indkey);
 	values[Anum_pg_index_indcollation - 1] = PointerGetDatum(indcollation);
 	values[Anum_pg_index_indclass - 1] = PointerGetDatum(indclass);
@@ -713,6 +716,8 @@ UpdateIndexRelation(Oid indexoid,
  *			already exists.
  *		INDEX_CREATE_PARTITIONED:
  *			create a partitioned index (table must be partitioned)
+ *		INDEX_CREATE_DISABLED:
+*				create the index as disabled if instructed, defaults to being enabled.
  * constr_flags: flags passed to index_constraint_create
  *		(only if INDEX_CREATE_ADD_CONSTRAINT is set)
  * allow_system_table_mods: allow table to be a system catalog
@@ -758,6 +763,7 @@ index_create(Relation heapRelation,
 	bool		invalid = (flags & INDEX_CREATE_INVALID) != 0;
 	bool		concurrent = (flags & INDEX_CREATE_CONCURRENT) != 0;
 	bool		partitioned = (flags & INDEX_CREATE_PARTITIONED) != 0;
+	bool 		isenabled  = (flags & INDEX_CREATE_ENABLED) != 0;
 	char		relkind;
 	TransactionId relfrozenxid;
 	MultiXactId relminmxid;
@@ -1041,13 +1047,15 @@ index_create(Relation heapRelation,
 	 *	  (Or, could define a rule to maintain the predicate) --Nels, Feb '92
 	 * ----------------
 	 */
+
 	UpdateIndexRelation(indexRelationId, heapRelationId, parentIndexRelid,
 						indexInfo,
 						collationIds, opclassIds, coloptions,
 						isprimary, is_exclusion,
 						(constr_flags & INDEX_CONSTR_CREATE_DEFERRABLE) == 0,
 						!concurrent && !invalid,
-						!concurrent);
+						!concurrent,
+						isenabled);
 
 	/*
 	 * Register relcache invalidation on the indexes' heap relation, to
@@ -1316,6 +1324,8 @@ index_concurrently_create_copy(Relation heapRelation, Oid oldIndexId,
 	List	   *indexColNames = NIL;
 	List	   *indexExprs = NIL;
 	List	   *indexPreds = NIL;
+	Form_pg_index indexForm;
+	bits16 	 createFlags;
 
 	indexRelation = index_open(oldIndexId, RowExclusiveLock);
 
@@ -1343,6 +1353,9 @@ index_concurrently_create_copy(Relation heapRelation, Oid oldIndexId,
 											Anum_pg_index_indoption);
 	indcoloptions = (int2vector *) DatumGetPointer(colOptionDatum);
 
+	/* Get the enabled state of the original index */
+	indexForm = (Form_pg_index) GETSTRUCT(indexTuple);
+
 	/* Fetch reloptions of index if any */
 	classTuple = SearchSysCache1(RELOID, ObjectIdGetDatum(oldIndexId));
 	if (!HeapTupleIsValid(classTuple))
@@ -1434,6 +1447,16 @@ index_concurrently_create_copy(Relation heapRelation, Oid oldIndexId,
 		stattargets[i].isnull = isnull;
 	}
 
+	/*
+	* Determine the create flags for the new index.
+	* We always use SKIP_BUILD and CONCURRENT for concurrent reindexing.
+	* If the original index was enabled, we also set the ENABLED flag
+	* to maintain the same state in the new index.
+	*/
+	createFlags = INDEX_CREATE_SKIP_BUILD | INDEX_CREATE_CONCURRENT;
+	if (indexForm->indisenabled)
+			createFlags |= INDEX_CREATE_ENABLED;
+
 	/*
 	 * Now create the new index.
 	 *
@@ -1457,7 +1480,7 @@ index_concurrently_create_copy(Relation heapRelation, Oid oldIndexId,
 							  indcoloptions->values,
 							  stattargets,
 							  reloptionsDatum,
-							  INDEX_CREATE_SKIP_BUILD | INDEX_CREATE_CONCURRENT,
+							  createFlags,
 							  0,
 							  true, /* allow table to be a system catalog? */
 							  false,	/* is_internal? */
diff --git a/src/backend/catalog/toasting.c b/src/backend/catalog/toasting.c
index ad3082c62a..dead993a74 100644
--- a/src/backend/catalog/toasting.c
+++ b/src/backend/catalog/toasting.c
@@ -325,7 +325,7 @@ create_toast_table(Relation rel, Oid toastOid, Oid toastIndexOid,
 				 BTREE_AM_OID,
 				 rel->rd_rel->reltablespace,
 				 collationIds, opclassIds, NULL, coloptions, NULL, (Datum) 0,
-				 INDEX_CREATE_IS_PRIMARY, 0, true, true, NULL);
+				 INDEX_CREATE_IS_PRIMARY | INDEX_CREATE_ENABLED, 0, true, true, NULL);
 
 	table_close(toast_rel, NoLock);
 
diff --git a/src/backend/commands/indexcmds.c b/src/backend/commands/indexcmds.c
index 4049ce1a10..b456069f94 100644
--- a/src/backend/commands/indexcmds.c
+++ b/src/backend/commands/indexcmds.c
@@ -1198,6 +1198,10 @@ DefineIndex(Oid tableId,
 		flags |= INDEX_CREATE_PARTITIONED;
 	if (stmt->primary)
 		flags |= INDEX_CREATE_IS_PRIMARY;
+   if (stmt->isenabled)
+		flags |= INDEX_CREATE_ENABLED;
+   else
+		flags &= ~INDEX_CREATE_ENABLED;
 
 	/*
 	 * If the table is partitioned, and recursion was declined but partitions
diff --git a/src/backend/commands/tablecmds.c b/src/backend/commands/tablecmds.c
index 4937478262..7535a4843d 100644
--- a/src/backend/commands/tablecmds.c
+++ b/src/backend/commands/tablecmds.c
@@ -688,7 +688,7 @@ static List *GetParentedForeignKeyRefs(Relation partition);
 static void ATDetachCheckNoForeignKeyRefs(Relation partition);
 static char GetAttributeCompression(Oid atttypid, const char *compression);
 static char GetAttributeStorage(Oid atttypid, const char *storagemode);
-
+static void ATExecEnableDisableIndex(Relation rel, bool enable);
 
 /* ----------------------------------------------------------------
  *		DefineRelation
@@ -4632,6 +4632,8 @@ AlterTableGetLockLevel(List *cmds)
 			case AT_SetExpression:
 			case AT_DropExpression:
 			case AT_SetCompression:
+			case AT_EnableIndex:
+			case AT_DisableIndex:
 				cmd_lockmode = AccessExclusiveLock;
 				break;
 
@@ -5194,6 +5196,12 @@ ATPrepCmd(List **wqueue, Relation rel, AlterTableCmd *cmd,
 			/* No command-specific prep needed */
 			pass = AT_PASS_MISC;
 			break;
+		case AT_EnableIndex:
+		case AT_DisableIndex:
+			ATSimplePermissions(cmd->subtype, rel, ATT_INDEX | ATT_PARTITIONED_INDEX);
+			/* No command-specific prep needed */
+			pass = AT_PASS_MISC;
+			break;
 		default:				/* oops */
 			elog(ERROR, "unrecognized alter table type: %d",
 				 (int) cmd->subtype);
@@ -5588,6 +5596,12 @@ ATExecCmd(List **wqueue, AlteredTableInfo *tab,
 		case AT_DetachPartitionFinalize:
 			address = ATExecDetachPartitionFinalize(rel, ((PartitionCmd *) cmd->def)->name);
 			break;
+		case AT_EnableIndex:
+				ATExecEnableDisableIndex(rel, true);
+				break;
+		case AT_DisableIndex:
+				ATExecEnableDisableIndex(rel, false);
+				break;
 		default:				/* oops */
 			elog(ERROR, "unrecognized alter table type: %d",
 				 (int) cmd->subtype);
@@ -6477,6 +6491,8 @@ alter_table_type_to_string(AlterTableType cmdtype)
 			return "DROP COLUMN";
 		case AT_AddIndex:
 		case AT_ReAddIndex:
+		case AT_EnableIndex:
+		case AT_DisableIndex:
 			return NULL;		/* not real grammar */
 		case AT_AddConstraint:
 		case AT_ReAddConstraint:
@@ -20812,3 +20828,52 @@ GetAttributeStorage(Oid atttypid, const char *storagemode)
 
 	return cstorage;
 }
+
+/*
+ * ATExecEnableDisableIndex
+ * Performs a catalog update to enable or disable an index in pg_index.
+ */
+static void
+ATExecEnableDisableIndex(Relation rel, bool enable)
+{
+	Oid         indexOid = RelationGetRelid(rel);
+	Relation    pg_index;
+	HeapTuple   indexTuple;
+	Form_pg_index indexForm;
+	bool        updated = false;
+
+	pg_index = table_open(IndexRelationId, RowExclusiveLock);
+
+	indexTuple = SearchSysCacheCopy1(INDEXRELID, ObjectIdGetDatum(indexOid));
+	if (!HeapTupleIsValid(indexTuple))
+		elog(ERROR, "could not find tuple for index %u", indexOid);
+
+	indexForm = (Form_pg_index) GETSTRUCT(indexTuple);
+	if (indexForm->indcheckxmin)
+	{
+		heap_freetuple(indexTuple);
+		table_close(pg_index, RowExclusiveLock);
+		ereport(ERROR,
+				(errcode(ERRCODE_OBJECT_NOT_IN_PREREQUISITE_STATE),
+				errmsg("cannot enable/disable index while indcheckxmin is true"),
+				errhint("Wait for all transactions that might see inconsistent HOT chains to complete")));
+	}
+
+	if (indexForm->indisenabled != enable)
+	{
+		indexForm->indisenabled = enable;
+
+		CatalogTupleUpdate(pg_index, &indexTuple->t_self, indexTuple);
+		updated = true;
+	}
+
+	heap_freetuple(indexTuple);
+	table_close(pg_index, RowExclusiveLock);
+
+	if (updated)
+	{
+		CacheInvalidateRelcache(rel);
+		InvokeObjectPostAlterHook(IndexRelationId, indexOid, 0);
+		CommandCounterIncrement();
+	}
+}
diff --git a/src/backend/optimizer/util/plancat.c b/src/backend/optimizer/util/plancat.c
index c31cc3ee69..f66e49d94e 100644
--- a/src/backend/optimizer/util/plancat.c
+++ b/src/backend/optimizer/util/plancat.c
@@ -254,13 +254,12 @@ get_relation_info(PlannerInfo *root, Oid relationObjectId, bool inhparent,
 			index = indexRelation->rd_index;
 
 			/*
-			 * Ignore invalid indexes, since they can't safely be used for
-			 * queries.  Note that this is OK because the data structure we
-			 * are constructing is only used by the planner --- the executor
-			 * still needs to insert into "invalid" indexes, if they're marked
-			 * indisready.
+			 * Ignore invalid or disabled indexes, since they can't safely be used for
+			 * queries. This is OK because the data structure we are constructing is
+			 * only used by the planner - the executor still needs to insert into
+			 * "invalid" indexes if they're marked indisready.
 			 */
-			if (!index->indisvalid)
+			if (!index->indisvalid || !index->indisenabled)
 			{
 				index_close(indexRelation, NoLock);
 				continue;
diff --git a/src/backend/parser/gram.y b/src/backend/parser/gram.y
index bd5ebb35c4..64749b9b4f 100644
--- a/src/backend/parser/gram.y
+++ b/src/backend/parser/gram.y
@@ -320,7 +320,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 %type <ival>	add_drop opt_asc_desc opt_nulls_order
 
 %type <node>	alter_table_cmd alter_type_cmd opt_collate_clause
-	   replica_identity partition_cmd index_partition_cmd
+	   replica_identity partition_cmd index_partition_cmd index_alter_cmd
 %type <list>	alter_table_cmds alter_type_cmds
 %type <list>    alter_identity_column_option_list
 %type <defelt>  alter_identity_column_option
@@ -483,6 +483,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 %type <boolean> opt_unique opt_verbose opt_full
 %type <boolean> opt_freeze opt_analyze opt_default
 %type <defelt>	opt_binary copy_delimiter
+%type <boolean>  opt_index_enabled
 
 %type <boolean> copy_from opt_program
 
@@ -2149,6 +2150,24 @@ AlterTableStmt:
 					n->nowait = $13;
 					$$ = (Node *) n;
 				}
+		| ALTER INDEX qualified_name index_alter_cmd
+				{
+					AlterTableStmt *n = makeNode(AlterTableStmt);
+					n->relation = $3;
+					n->cmds = list_make1($4);
+					n->objtype = OBJECT_INDEX;
+					n->missing_ok = false;
+					$$ = (Node *) n;
+				}
+		| ALTER INDEX IF_P EXISTS qualified_name index_alter_cmd
+				{
+					AlterTableStmt *n = makeNode(AlterTableStmt);
+					n->relation = $5;
+					n->cmds = list_make1($6);
+					n->objtype = OBJECT_INDEX;
+					n->missing_ok = true;
+					$$ = (Node *) n;
+				}
 		|	ALTER INDEX qualified_name alter_table_cmds
 				{
 					AlterTableStmt *n = makeNode(AlterTableStmt);
@@ -2374,6 +2393,21 @@ index_partition_cmd:
 				}
 		;
 
+index_alter_cmd:
+		/* ALTER INDEX <name> ENABLE|DISABLE */
+		ENABLE_P
+			{
+				AlterTableCmd *n = makeNode(AlterTableCmd);
+				n->subtype = AT_EnableIndex;
+				$$ = (Node *) n;
+			}
+		| DISABLE_P
+			{
+				AlterTableCmd *n = makeNode(AlterTableCmd);
+				n->subtype = AT_DisableIndex;
+				$$ = (Node *) n;
+			}
+		;
 alter_table_cmd:
 			/* ALTER TABLE <name> ADD <coldef> */
 			ADD_P columnDef
@@ -8129,7 +8163,7 @@ defacl_privilege_target:
 
 IndexStmt:	CREATE opt_unique INDEX opt_concurrently opt_single_name
 			ON relation_expr access_method_clause '(' index_params ')'
-			opt_include opt_unique_null_treatment opt_reloptions OptTableSpace where_clause
+			opt_include opt_unique_null_treatment opt_reloptions OptTableSpace where_clause opt_index_enabled
 				{
 					IndexStmt *n = makeNode(IndexStmt);
 
@@ -8144,6 +8178,7 @@ IndexStmt:	CREATE opt_unique INDEX opt_concurrently opt_single_name
 					n->options = $14;
 					n->tableSpace = $15;
 					n->whereClause = $16;
+					n->isenabled = $17;
 					n->excludeOpNames = NIL;
 					n->idxcomment = NULL;
 					n->indexOid = InvalidOid;
@@ -8161,7 +8196,7 @@ IndexStmt:	CREATE opt_unique INDEX opt_concurrently opt_single_name
 				}
 			| CREATE opt_unique INDEX opt_concurrently IF_P NOT EXISTS name
 			ON relation_expr access_method_clause '(' index_params ')'
-			opt_include opt_unique_null_treatment opt_reloptions OptTableSpace where_clause
+			opt_include opt_unique_null_treatment opt_reloptions OptTableSpace where_clause opt_index_enabled
 				{
 					IndexStmt *n = makeNode(IndexStmt);
 
@@ -8176,6 +8211,7 @@ IndexStmt:	CREATE opt_unique INDEX opt_concurrently opt_single_name
 					n->options = $17;
 					n->tableSpace = $18;
 					n->whereClause = $19;
+					n->isenabled = $20;
 					n->excludeOpNames = NIL;
 					n->idxcomment = NULL;
 					n->indexOid = InvalidOid;
@@ -8198,6 +8234,12 @@ opt_unique:
 			| /*EMPTY*/								{ $$ = false; }
 		;
 
+opt_index_enabled:
+			ENABLE_P                      { $$ = true; }
+			| DISABLE_P                   { $$ = false; }
+			| /*EMPTY*/                 	{ $$ = true; }
+		;
+
 access_method_clause:
 			USING name								{ $$ = $2; }
 			| /*EMPTY*/								{ $$ = DEFAULT_INDEX_TYPE; }
diff --git a/src/backend/parser/parse_utilcmd.c b/src/backend/parser/parse_utilcmd.c
index 95dad76683..41a8e57f3d 100644
--- a/src/backend/parser/parse_utilcmd.c
+++ b/src/backend/parser/parse_utilcmd.c
@@ -1736,6 +1736,7 @@ generateClonedIndexStmt(RangeVar *heapRel, Relation source_idx,
 	index->concurrent = false;
 	index->if_not_exists = false;
 	index->reset_default_tblspc = false;
+	index->isenabled = idxrec->indisenabled;
 
 	/*
 	 * We don't try to preserve the name of the source index; instead, just
@@ -2357,6 +2358,8 @@ transformIndexConstraint(Constraint *constraint, CreateStmtContext *cxt)
 	index->concurrent = false;
 	index->if_not_exists = false;
 	index->reset_default_tblspc = constraint->reset_default_tblspc;
+	/* Ensure indexes for constraints are created as enabled by default */
+	index->isenabled = true;
 
 	/*
 	 * If it's ALTER TABLE ADD CONSTRAINT USING INDEX, look up the index and
diff --git a/src/backend/utils/adt/ruleutils.c b/src/backend/utils/adt/ruleutils.c
index be1f1f50b7..2c403a08fe 100644
--- a/src/backend/utils/adt/ruleutils.c
+++ b/src/backend/utils/adt/ruleutils.c
@@ -1559,6 +1559,10 @@ pg_get_indexdef_worker(Oid indexrelid, int colno,
 			else
 				appendStringInfo(&buf, " WHERE %s", str);
 		}
+
+		/* Add DISABLE clause if the index is disabled */
+		if (!idxrec->indisenabled)
+				appendStringInfoString(&buf, " DISABLE");
 	}
 
 	/* Clean up */
diff --git a/src/backend/utils/cache/relcache.c b/src/backend/utils/cache/relcache.c
index 1ce7eb9da8..e343c6916f 100644
--- a/src/backend/utils/cache/relcache.c
+++ b/src/backend/utils/cache/relcache.c
@@ -2311,6 +2311,7 @@ RelationReloadIndexInfo(Relation relation)
 		relation->rd_index->indisready = index->indisready;
 		relation->rd_index->indislive = index->indislive;
 		relation->rd_index->indisreplident = index->indisreplident;
+		relation->rd_index->indisenabled = index->indisenabled;
 
 		/* Copy xmin too, as that is needed to make sense of indcheckxmin */
 		HeapTupleHeaderSetXmin(relation->rd_indextuple->t_data,
diff --git a/src/include/catalog/index.h b/src/include/catalog/index.h
index 2dea96f47c..8a47cfd174 100644
--- a/src/include/catalog/index.h
+++ b/src/include/catalog/index.h
@@ -65,6 +65,7 @@ extern void index_check_primary_key(Relation heapRel,
 #define	INDEX_CREATE_IF_NOT_EXISTS			(1 << 4)
 #define	INDEX_CREATE_PARTITIONED			(1 << 5)
 #define INDEX_CREATE_INVALID				(1 << 6)
+#define INDEX_CREATE_ENABLED        (1 << 7)
 
 extern Oid	index_create(Relation heapRelation,
 						 const char *indexRelationName,
@@ -175,7 +176,6 @@ extern void RestoreReindexState(const void *reindexstate);
 
 extern void IndexSetParentIndex(Relation partitionIdx, Oid parentOid);
 
-
 /*
  * itemptr_encode - Encode ItemPointer as int64/int8
  *
diff --git a/src/include/catalog/pg_index.h b/src/include/catalog/pg_index.h
index 6c89639a9e..b0c7e5f365 100644
--- a/src/include/catalog/pg_index.h
+++ b/src/include/catalog/pg_index.h
@@ -44,6 +44,7 @@ CATALOG(pg_index,2610,IndexRelationId) BKI_SCHEMA_MACRO
 	bool		indisready;		/* is this index ready for inserts? */
 	bool		indislive;		/* is this index alive at all? */
 	bool		indisreplident; /* is this index the identity for replication? */
+	bool		indisenabled;	/* is this index enabled for use by queries? */
 
 	/* variable-length fields start here, but we allow direct access to indkey */
 	int2vector	indkey BKI_FORCE_NOT_NULL;	/* column numbers of indexed cols,
diff --git a/src/include/nodes/parsenodes.h b/src/include/nodes/parsenodes.h
index 0f9462493e..5054f9f8bb 100644
--- a/src/include/nodes/parsenodes.h
+++ b/src/include/nodes/parsenodes.h
@@ -2423,6 +2423,8 @@ typedef enum AlterTableType
 	AT_SetIdentity,				/* SET identity column options */
 	AT_DropIdentity,			/* DROP IDENTITY */
 	AT_ReAddStatistics,			/* internal to commands/tablecmds.c */
+	AT_EnableIndex,					/* ENABLE INDEX */
+	AT_DisableIndex,				/* DISABLE INDEX */
 } AlterTableType;
 
 typedef struct ReplicaIdentityStmt
@@ -3402,6 +3404,7 @@ typedef struct IndexStmt
 	bool		if_not_exists;	/* just do nothing if index already exists? */
 	bool		reset_default_tblspc;	/* reset default_tablespace prior to
 										 * executing */
+  bool		isenabled;		/* true if ENABLE (default), false if DISABLE */
 } IndexStmt;
 
 /* ----------------------
diff --git a/src/include/nodes/pathnodes.h b/src/include/nodes/pathnodes.h
index 58748d2ca6..be77186c87 100644
--- a/src/include/nodes/pathnodes.h
+++ b/src/include/nodes/pathnodes.h
@@ -1212,6 +1212,8 @@ struct IndexOptInfo
 	/* AM's cost estimator */
 	/* Rather than include amapi.h here, we declare amcostestimate like this */
 	void		(*amcostestimate) (struct PlannerInfo *, struct IndexPath *, double, Cost *, Cost *, Selectivity *, double *, double *) pg_node_attr(read_write_ignore);
+	/* true if this index is enabled */
+	bool		enabled;
 };
 
 /*
diff --git a/src/test/regress/expected/create_index.out b/src/test/regress/expected/create_index.out
index 1904eb65bb..8e4952ca60 100644
--- a/src/test/regress/expected/create_index.out
+++ b/src/test/regress/expected/create_index.out
@@ -3318,6 +3318,511 @@ ERROR:  REINDEX SCHEMA cannot run inside a transaction block
 END;
 -- concurrently
 REINDEX SCHEMA CONCURRENTLY schema_to_reindex;
+-- Test enable/disable functionality for indexes
+CREATE TABLE index_test(
+    id INT PRIMARY KEY,
+    data TEXT,
+    num INT,
+    vector INT[],
+    range INT4RANGE
+);
+INSERT INTO index_test
+SELECT
+    g,
+    'data ' || g,
+    g % 100,
+    ARRAY[g, g+1, g+2],
+    int4range(g, g+10)
+FROM generate_series(1, 1000) g;
+-- Function for testing
+CREATE FUNCTION get_data_length(text) RETURNS INT AS $$
+    SELECT length($1);
+$$ LANGUAGE SQL IMMUTABLE;
+-- Helper function to show index status
+CREATE OR REPLACE FUNCTION show_index_status(index_name text)
+RETURNS TABLE (
+    indexrelid regclass,
+    indisvalid boolean,
+    indisready boolean,
+    indislive boolean,
+    indisenabled boolean
+) AS $$
+BEGIN
+    RETURN QUERY EXECUTE format('
+        SELECT indexrelid::regclass, indisvalid, indisready, indislive, indisenabled
+        FROM pg_index
+        WHERE indexrelid = %L::regclass', index_name);
+END;
+$$ LANGUAGE plpgsql;
+-- Create and test each index type
+-- 1. Basic single-column index
+CREATE INDEX idx_single ON index_test(data);
+SELECT show_index_status('idx_single');
+  show_index_status   
+----------------------
+ (idx_single,t,t,t,t)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE data = 'data 500';
+                  QUERY PLAN                   
+-----------------------------------------------
+ Bitmap Heap Scan on index_test
+   Recheck Cond: (data = 'data 500'::text)
+   ->  Bitmap Index Scan on idx_single
+         Index Cond: (data = 'data 500'::text)
+(4 rows)
+
+ALTER INDEX idx_single DISABLE;
+SELECT show_index_status('idx_single');
+  show_index_status   
+----------------------
+ (idx_single,t,t,t,f)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE data = 'data 500';
+             QUERY PLAN              
+-------------------------------------
+ Seq Scan on index_test
+   Filter: (data = 'data 500'::text)
+(2 rows)
+
+ALTER INDEX idx_single ENABLE;
+SELECT show_index_status('idx_single');
+  show_index_status   
+----------------------
+ (idx_single,t,t,t,t)
+(1 row)
+
+-- 2. Multi-column index
+CREATE INDEX idx_multi ON index_test(num, data);
+SELECT show_index_status('idx_multi');
+  show_index_status  
+---------------------
+ (idx_multi,t,t,t,t)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE num = 50 AND data > 'data 500';
+                           QUERY PLAN                           
+----------------------------------------------------------------
+ Bitmap Heap Scan on index_test
+   Recheck Cond: ((num = 50) AND (data > 'data 500'::text))
+   ->  Bitmap Index Scan on idx_multi
+         Index Cond: ((num = 50) AND (data > 'data 500'::text))
+(4 rows)
+
+ALTER INDEX idx_multi DISABLE;
+SELECT show_index_status('idx_multi');
+  show_index_status  
+---------------------
+ (idx_multi,t,t,t,f)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE num = 50 AND data > 'data 500';
+                      QUERY PLAN                      
+------------------------------------------------------
+ Seq Scan on index_test
+   Filter: ((data > 'data 500'::text) AND (num = 50))
+(2 rows)
+
+ALTER INDEX idx_multi ENABLE;
+SELECT show_index_status('idx_multi');
+  show_index_status  
+---------------------
+ (idx_multi,t,t,t,t)
+(1 row)
+
+-- 3. Partial index
+CREATE INDEX idx_partial ON index_test(num) WHERE num < 50;
+SELECT show_index_status('idx_partial');
+   show_index_status   
+-----------------------
+ (idx_partial,t,t,t,t)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE num = 25;
+               QUERY PLAN               
+----------------------------------------
+ Bitmap Heap Scan on index_test
+   Recheck Cond: (num = 25)
+   ->  Bitmap Index Scan on idx_partial
+         Index Cond: (num = 25)
+(4 rows)
+
+ALTER INDEX idx_partial DISABLE;
+SELECT show_index_status('idx_partial');
+   show_index_status   
+-----------------------
+ (idx_partial,t,t,t,f)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE num = 25;
+              QUERY PLAN              
+--------------------------------------
+ Bitmap Heap Scan on index_test
+   Recheck Cond: (num = 25)
+   ->  Bitmap Index Scan on idx_multi
+         Index Cond: (num = 25)
+(4 rows)
+
+ALTER INDEX idx_partial ENABLE;
+SELECT show_index_status('idx_partial');
+   show_index_status   
+-----------------------
+ (idx_partial,t,t,t,t)
+(1 row)
+
+-- 4. Expression index
+CREATE INDEX idx_expression ON index_test((lower(data)));
+SELECT show_index_status('idx_expression');
+    show_index_status     
+--------------------------
+ (idx_expression,t,t,t,t)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE lower(data) = 'data 500';
+                      QUERY PLAN                      
+------------------------------------------------------
+ Bitmap Heap Scan on index_test
+   Recheck Cond: (lower(data) = 'data 500'::text)
+   ->  Bitmap Index Scan on idx_expression
+         Index Cond: (lower(data) = 'data 500'::text)
+(4 rows)
+
+ALTER INDEX idx_expression DISABLE;
+SELECT show_index_status('idx_expression');
+    show_index_status     
+--------------------------
+ (idx_expression,t,t,t,f)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE lower(data) = 'data 500';
+                 QUERY PLAN                 
+--------------------------------------------
+ Seq Scan on index_test
+   Filter: (lower(data) = 'data 500'::text)
+(2 rows)
+
+ALTER INDEX idx_expression ENABLE;
+SELECT show_index_status('idx_expression');
+    show_index_status     
+--------------------------
+ (idx_expression,t,t,t,t)
+(1 row)
+
+-- 5. GIN index
+CREATE INDEX idx_gin ON index_test USING gin(vector);
+SELECT show_index_status('idx_gin');
+ show_index_status 
+-------------------
+ (idx_gin,t,t,t,t)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE vector @> ARRAY[500];
+                     QUERY PLAN                     
+----------------------------------------------------
+ Bitmap Heap Scan on index_test
+   Recheck Cond: (vector @> '{500}'::integer[])
+   ->  Bitmap Index Scan on idx_gin
+         Index Cond: (vector @> '{500}'::integer[])
+(4 rows)
+
+ALTER INDEX idx_gin DISABLE;
+SELECT show_index_status('idx_gin');
+ show_index_status 
+-------------------
+ (idx_gin,t,t,t,f)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE vector @> ARRAY[500];
+                QUERY PLAN                
+------------------------------------------
+ Seq Scan on index_test
+   Filter: (vector @> '{500}'::integer[])
+(2 rows)
+
+ALTER INDEX idx_gin ENABLE;
+SELECT show_index_status('idx_gin');
+ show_index_status 
+-------------------
+ (idx_gin,t,t,t,t)
+(1 row)
+
+-- 6. GiST index
+CREATE INDEX idx_gist ON index_test USING gist(range);
+SELECT show_index_status('idx_gist');
+ show_index_status  
+--------------------
+ (idx_gist,t,t,t,t)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE range && int4range(100, 110);
+                      QUERY PLAN                       
+-------------------------------------------------------
+ Bitmap Heap Scan on index_test
+   Recheck Cond: (range && '[100,110)'::int4range)
+   ->  Bitmap Index Scan on idx_gist
+         Index Cond: (range && '[100,110)'::int4range)
+(4 rows)
+
+ALTER INDEX idx_gist DISABLE;
+SELECT show_index_status('idx_gist');
+ show_index_status  
+--------------------
+ (idx_gist,t,t,t,f)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE range && int4range(100, 110);
+                 QUERY PLAN                  
+---------------------------------------------
+ Seq Scan on index_test
+   Filter: (range && '[100,110)'::int4range)
+(2 rows)
+
+ALTER INDEX idx_gist ENABLE;
+SELECT show_index_status('idx_gist');
+ show_index_status  
+--------------------
+ (idx_gist,t,t,t,t)
+(1 row)
+
+-- 7. Covering index
+CREATE INDEX idx_covering ON index_test(num) INCLUDE (data);
+SELECT show_index_status('idx_covering');
+   show_index_status    
+------------------------
+ (idx_covering,t,t,t,t)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT num, data FROM index_test WHERE num = 50;
+               QUERY PLAN                
+-----------------------------------------
+ Bitmap Heap Scan on index_test
+   Recheck Cond: (num = 50)
+   ->  Bitmap Index Scan on idx_covering
+         Index Cond: (num = 50)
+(4 rows)
+
+ALTER INDEX idx_covering DISABLE;
+SELECT show_index_status('idx_covering');
+   show_index_status    
+------------------------
+ (idx_covering,t,t,t,f)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT num, data FROM index_test WHERE num = 50;
+              QUERY PLAN              
+--------------------------------------
+ Bitmap Heap Scan on index_test
+   Recheck Cond: (num = 50)
+   ->  Bitmap Index Scan on idx_multi
+         Index Cond: (num = 50)
+(4 rows)
+
+ALTER INDEX idx_covering ENABLE;
+SELECT show_index_status('idx_covering');
+   show_index_status    
+------------------------
+ (idx_covering,t,t,t,t)
+(1 row)
+
+-- 8. Unique index
+CREATE UNIQUE INDEX idx_unique ON index_test(id, data);
+SELECT show_index_status('idx_unique');
+  show_index_status   
+----------------------
+ (idx_unique,t,t,t,t)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE id = 500 AND data = 'data 500';
+                        QUERY PLAN                        
+----------------------------------------------------------
+ Index Scan using idx_unique on index_test
+   Index Cond: ((id = 500) AND (data = 'data 500'::text))
+(2 rows)
+
+ALTER INDEX idx_unique DISABLE;
+SELECT show_index_status('idx_unique');
+  show_index_status   
+----------------------
+ (idx_unique,t,t,t,f)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE id = 500 AND data = 'data 500';
+                   QUERY PLAN                   
+------------------------------------------------
+ Index Scan using index_test_pkey on index_test
+   Index Cond: (id = 500)
+   Filter: (data = 'data 500'::text)
+(3 rows)
+
+ALTER INDEX idx_unique ENABLE;
+SELECT show_index_status('idx_unique');
+  show_index_status   
+----------------------
+ (idx_unique,t,t,t,t)
+(1 row)
+
+-- 9. Function-based index
+CREATE INDEX idx_func ON index_test(get_data_length(data));
+SELECT show_index_status('idx_func');
+ show_index_status  
+--------------------
+ (idx_func,t,t,t,t)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE get_data_length(data) = 10;
+               QUERY PLAN                
+-----------------------------------------
+ Bitmap Heap Scan on index_test
+   Recheck Cond: (length(data) = 10)
+   ->  Bitmap Index Scan on idx_func
+         Index Cond: (length(data) = 10)
+(4 rows)
+
+ALTER INDEX idx_func DISABLE;
+SELECT show_index_status('idx_func');
+ show_index_status  
+--------------------
+ (idx_func,t,t,t,f)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE get_data_length(data) = 10;
+          QUERY PLAN           
+-------------------------------
+ Seq Scan on index_test
+   Filter: (length(data) = 10)
+(2 rows)
+
+ALTER INDEX idx_func ENABLE;
+SELECT show_index_status('idx_func');
+ show_index_status  
+--------------------
+ (idx_func,t,t,t,t)
+(1 row)
+
+-- 10. Join index
+CREATE TABLE join_test (id INT PRIMARY KEY, ref_id INT);
+INSERT INTO join_test SELECT g, g % 100 FROM generate_series(1, 1000) g;
+CREATE INDEX idx_join ON join_test(ref_id);
+SELECT show_index_status('idx_join');
+ show_index_status  
+--------------------
+ (idx_join,t,t,t,t)
+(1 row)
+
+EXPLAIN (COSTS OFF)
+SELECT jt.id, it.data
+FROM join_test jt
+JOIN index_test it ON jt.ref_id = it.num
+WHERE jt.id BETWEEN 100 AND 200;
+                          QUERY PLAN                           
+---------------------------------------------------------------
+ Hash Join
+   Hash Cond: (it.num = jt.ref_id)
+   ->  Seq Scan on index_test it
+   ->  Hash
+         ->  Bitmap Heap Scan on join_test jt
+               Recheck Cond: ((id >= 100) AND (id <= 200))
+               ->  Bitmap Index Scan on join_test_pkey
+                     Index Cond: ((id >= 100) AND (id <= 200))
+(8 rows)
+
+-- Disable all indexes to force seq scan
+ALTER INDEX idx_join DISABLE;
+ALTER INDEX join_test_pkey DISABLE;
+SELECT show_index_status('idx_join');
+ show_index_status  
+--------------------
+ (idx_join,t,t,t,f)
+(1 row)
+
+SELECT show_index_status('join_test_pkey');
+    show_index_status     
+--------------------------
+ (join_test_pkey,t,t,t,f)
+(1 row)
+
+EXPLAIN (COSTS OFF)
+SELECT jt.id, it.data
+FROM join_test jt
+JOIN index_test it ON jt.ref_id = it.num
+WHERE jt.id BETWEEN 100 AND 200;
+                     QUERY PLAN                      
+-----------------------------------------------------
+ Hash Join
+   Hash Cond: (it.num = jt.ref_id)
+   ->  Seq Scan on index_test it
+   ->  Hash
+         ->  Seq Scan on join_test jt
+               Filter: ((id >= 100) AND (id <= 200))
+(6 rows)
+
+ALTER INDEX idx_join ENABLE;
+ALTER INDEX join_test_pkey ENABLE;
+SELECT show_index_status('idx_join');
+ show_index_status  
+--------------------
+ (idx_join,t,t,t,t)
+(1 row)
+
+SELECT show_index_status('join_test_pkey');
+    show_index_status     
+--------------------------
+ (join_test_pkey,t,t,t,t)
+(1 row)
+
+-- Test REINDEX CONCURRENTLY
+REINDEX INDEX CONCURRENTLY idx_join;
+SELECT show_index_status('idx_join');
+ show_index_status  
+--------------------
+ (idx_join,t,t,t,t)
+(1 row)
+
+ALTER INDEX idx_join DISABLE;
+SELECT show_index_status('idx_join');
+ show_index_status  
+--------------------
+ (idx_join,t,t,t,f)
+(1 row)
+
+REINDEX INDEX CONCURRENTLY idx_join;
+SELECT show_index_status('idx_join');
+ show_index_status  
+--------------------
+ (idx_join,t,t,t,f)
+(1 row)
+
+SELECT pg_get_indexdef('idx_join'::regclass);
+                                  pg_get_indexdef                                  
+-----------------------------------------------------------------------------------
+ CREATE INDEX idx_join ON schema_to_reindex.join_test USING btree (ref_id) DISABLE
+(1 row)
+
+ALTER INDEX idx_join ENABLE;
+SELECT pg_get_indexdef('idx_join'::regclass);
+                              pg_get_indexdef                              
+---------------------------------------------------------------------------
+ CREATE INDEX idx_join ON schema_to_reindex.join_test USING btree (ref_id)
+(1 row)
+
+-- Test enable/disable index with indcheckxmin being true
+CREATE TABLE indcheckxmin_test(id int PRIMARY KEY);
+INSERT INTO indcheckxmin_test VALUES (1), (2), (3);
+CREATE INDEX CONCURRENTLY idx_checkxmin ON indcheckxmin_test(id);
+BEGIN;
+-- Simulate indcheckxmin being true
+UPDATE pg_index SET indcheckxmin = true WHERE indexrelid = 'idx_checkxmin'::regclass;
+ALTER INDEX idx_checkxmin DISABLE;  -- expect fail
+ERROR:  cannot enable/disable index while indcheckxmin is true
+HINT:  Wait for all transactions that might see inconsistent HOT chains to complete
+ROLLBACK;
+-- Clean up
+DROP TABLE index_test;
+DROP TABLE join_test;
+DROP FUNCTION get_data_length;
+DROP FUNCTION show_index_status;
+DROP TABLE indcheckxmin_test CASCADE;
 -- Failure for unauthorized user
 CREATE ROLE regress_reindexuser NOLOGIN;
 SET SESSION ROLE regress_reindexuser;
diff --git a/src/test/regress/sql/create_index.sql b/src/test/regress/sql/create_index.sql
index c085e05f05..2d61ff2f9b 100644
--- a/src/test/regress/sql/create_index.sql
+++ b/src/test/regress/sql/create_index.sql
@@ -1410,6 +1410,198 @@ END;
 -- concurrently
 REINDEX SCHEMA CONCURRENTLY schema_to_reindex;
 
+-- Test enable/disable functionality for indexes
+
+CREATE TABLE index_test(
+    id INT PRIMARY KEY,
+    data TEXT,
+    num INT,
+    vector INT[],
+    range INT4RANGE
+);
+
+INSERT INTO index_test
+SELECT
+    g,
+    'data ' || g,
+    g % 100,
+    ARRAY[g, g+1, g+2],
+    int4range(g, g+10)
+FROM generate_series(1, 1000) g;
+
+-- Function for testing
+CREATE FUNCTION get_data_length(text) RETURNS INT AS $$
+    SELECT length($1);
+$$ LANGUAGE SQL IMMUTABLE;
+
+-- Helper function to show index status
+CREATE OR REPLACE FUNCTION show_index_status(index_name text)
+RETURNS TABLE (
+    indexrelid regclass,
+    indisvalid boolean,
+    indisready boolean,
+    indislive boolean,
+    indisenabled boolean
+) AS $$
+BEGIN
+    RETURN QUERY EXECUTE format('
+        SELECT indexrelid::regclass, indisvalid, indisready, indislive, indisenabled
+        FROM pg_index
+        WHERE indexrelid = %L::regclass', index_name);
+END;
+$$ LANGUAGE plpgsql;
+
+-- Create and test each index type
+-- 1. Basic single-column index
+CREATE INDEX idx_single ON index_test(data);
+SELECT show_index_status('idx_single');
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE data = 'data 500';
+ALTER INDEX idx_single DISABLE;
+SELECT show_index_status('idx_single');
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE data = 'data 500';
+ALTER INDEX idx_single ENABLE;
+SELECT show_index_status('idx_single');
+
+-- 2. Multi-column index
+CREATE INDEX idx_multi ON index_test(num, data);
+SELECT show_index_status('idx_multi');
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE num = 50 AND data > 'data 500';
+ALTER INDEX idx_multi DISABLE;
+SELECT show_index_status('idx_multi');
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE num = 50 AND data > 'data 500';
+ALTER INDEX idx_multi ENABLE;
+SELECT show_index_status('idx_multi');
+
+-- 3. Partial index
+CREATE INDEX idx_partial ON index_test(num) WHERE num < 50;
+SELECT show_index_status('idx_partial');
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE num = 25;
+ALTER INDEX idx_partial DISABLE;
+SELECT show_index_status('idx_partial');
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE num = 25;
+ALTER INDEX idx_partial ENABLE;
+SELECT show_index_status('idx_partial');
+
+-- 4. Expression index
+CREATE INDEX idx_expression ON index_test((lower(data)));
+SELECT show_index_status('idx_expression');
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE lower(data) = 'data 500';
+ALTER INDEX idx_expression DISABLE;
+SELECT show_index_status('idx_expression');
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE lower(data) = 'data 500';
+ALTER INDEX idx_expression ENABLE;
+SELECT show_index_status('idx_expression');
+
+-- 5. GIN index
+CREATE INDEX idx_gin ON index_test USING gin(vector);
+SELECT show_index_status('idx_gin');
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE vector @> ARRAY[500];
+ALTER INDEX idx_gin DISABLE;
+SELECT show_index_status('idx_gin');
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE vector @> ARRAY[500];
+ALTER INDEX idx_gin ENABLE;
+SELECT show_index_status('idx_gin');
+
+-- 6. GiST index
+CREATE INDEX idx_gist ON index_test USING gist(range);
+SELECT show_index_status('idx_gist');
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE range && int4range(100, 110);
+ALTER INDEX idx_gist DISABLE;
+SELECT show_index_status('idx_gist');
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE range && int4range(100, 110);
+ALTER INDEX idx_gist ENABLE;
+SELECT show_index_status('idx_gist');
+
+-- 7. Covering index
+CREATE INDEX idx_covering ON index_test(num) INCLUDE (data);
+SELECT show_index_status('idx_covering');
+EXPLAIN (COSTS OFF) SELECT num, data FROM index_test WHERE num = 50;
+ALTER INDEX idx_covering DISABLE;
+SELECT show_index_status('idx_covering');
+EXPLAIN (COSTS OFF) SELECT num, data FROM index_test WHERE num = 50;
+ALTER INDEX idx_covering ENABLE;
+SELECT show_index_status('idx_covering');
+
+-- 8. Unique index
+CREATE UNIQUE INDEX idx_unique ON index_test(id, data);
+SELECT show_index_status('idx_unique');
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE id = 500 AND data = 'data 500';
+ALTER INDEX idx_unique DISABLE;
+SELECT show_index_status('idx_unique');
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE id = 500 AND data = 'data 500';
+ALTER INDEX idx_unique ENABLE;
+SELECT show_index_status('idx_unique');
+
+-- 9. Function-based index
+CREATE INDEX idx_func ON index_test(get_data_length(data));
+SELECT show_index_status('idx_func');
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE get_data_length(data) = 10;
+ALTER INDEX idx_func DISABLE;
+SELECT show_index_status('idx_func');
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE get_data_length(data) = 10;
+ALTER INDEX idx_func ENABLE;
+SELECT show_index_status('idx_func');
+
+-- 10. Join index
+CREATE TABLE join_test (id INT PRIMARY KEY, ref_id INT);
+INSERT INTO join_test SELECT g, g % 100 FROM generate_series(1, 1000) g;
+CREATE INDEX idx_join ON join_test(ref_id);
+SELECT show_index_status('idx_join');
+
+EXPLAIN (COSTS OFF)
+SELECT jt.id, it.data
+FROM join_test jt
+JOIN index_test it ON jt.ref_id = it.num
+WHERE jt.id BETWEEN 100 AND 200;
+
+-- Disable all indexes to force seq scan
+ALTER INDEX idx_join DISABLE;
+ALTER INDEX join_test_pkey DISABLE;
+SELECT show_index_status('idx_join');
+SELECT show_index_status('join_test_pkey');
+
+EXPLAIN (COSTS OFF)
+SELECT jt.id, it.data
+FROM join_test jt
+JOIN index_test it ON jt.ref_id = it.num
+WHERE jt.id BETWEEN 100 AND 200;
+
+ALTER INDEX idx_join ENABLE;
+ALTER INDEX join_test_pkey ENABLE;
+SELECT show_index_status('idx_join');
+SELECT show_index_status('join_test_pkey');
+
+-- Test REINDEX CONCURRENTLY
+REINDEX INDEX CONCURRENTLY idx_join;
+SELECT show_index_status('idx_join');
+
+ALTER INDEX idx_join DISABLE;
+SELECT show_index_status('idx_join');
+REINDEX INDEX CONCURRENTLY idx_join;
+SELECT show_index_status('idx_join');
+
+SELECT pg_get_indexdef('idx_join'::regclass);
+ALTER INDEX idx_join ENABLE;
+SELECT pg_get_indexdef('idx_join'::regclass);
+
+-- Test enable/disable index with indcheckxmin being true
+
+CREATE TABLE indcheckxmin_test(id int PRIMARY KEY);
+INSERT INTO indcheckxmin_test VALUES (1), (2), (3);
+CREATE INDEX CONCURRENTLY idx_checkxmin ON indcheckxmin_test(id);
+BEGIN;
+-- Simulate indcheckxmin being true
+UPDATE pg_index SET indcheckxmin = true WHERE indexrelid = 'idx_checkxmin'::regclass;
+ALTER INDEX idx_checkxmin DISABLE;  -- expect fail
+ROLLBACK;
+
+-- Clean up
+DROP TABLE index_test;
+DROP TABLE join_test;
+DROP FUNCTION get_data_length;
+DROP FUNCTION show_index_status;
+DROP TABLE indcheckxmin_test CASCADE;
+
 -- Failure for unauthorized user
 CREATE ROLE regress_reindexuser NOLOGIN;
 SET SESSION ROLE regress_reindexuser;
-- 
2.39.5 (Apple Git-154)

#51Sami Imseih
samimseih@gmail.com
In reply to: Shayon Mukherjee (#50)
Re: Proposal to Enable/Disable Index using ALTER INDEX (with patch)

Rebased with the latest master as well.

Hi,

This is a great, long needed feature. Thanks for doing this.

I am late to this thread, but I took a look at the current patch
and have some comments as I continue to look.

1/
instead of

+       If true, the index is currently enabled and should be used for queries.
+       If false, the index is disabled and should not be used for queries,

how about?

"If true, the index is currently enabled and may be used for queries.
If false, the index is disabled and may not be used for queries,"

"may" is more accurate than "should" in this context.

2/
instead of

+ but is still maintained when the table is modified. Default is true.

how about?

"but is still updated when the table is modified. Default is true."

"update" of an index is the current verb used. See bottom of
https://www.postgresql.org/docs/current/indexes-intro.html

3/
instead of saying "used by the query planner for query optimization",
can it just be "The index will be used for queries."

+     <para>
+      Enable the specified index. The index will be used by the query planner
+      for query optimization. This is the default state for newly
created indexes.
+     </para>

Same for

+    <listitem>
+     <para>
+      Disable the specified index. A disabled index is not used by
the query planner
+      for query optimization, but it is still maintained when the
underlying table
+      data changes and will still be used to enforce constraints
(such as UNIQUE,
+      or PRIMARY KEY constraints).

4/ Should documentation recommend a direct catalog update?

+      to identify potentially unused indexes. Note that if you want
to completely
+      prevent an index from being used, including for constraint
enforcement, you
+      would need to mark it as invalid using a direct update to the
system catalogs
+      (e.g., <literal>UPDATE pg_index SET indisvalid = false WHERE
indexrelid = 'index_name'::regclass</literal>).

"indisvalid" does not control constraint enforcement in this case. It will be
"indisready" being set to false that will.

But even then, this goes against the general principle ( also documnted )
of not updating the catalog directly. See [1]https://www.postgresql.org/docs/current/catalogs.html

I think this part should be removed.

5/

In a case of a prepared statement, disabling the index
has no effect.

postgres=# create table foo ( id int primary key );
CREATE TABLE
postgres=# prepare prp as select * from foo where id = 1;
PREPARE
postgres=# explain analyze execute prp;
QUERY PLAN
-------------------------------------------------------------------------------------------------------------------
Index Only Scan using foo_pkey on foo (cost=0.15..8.17 rows=1
width=4) (actual time=0.018..0.019 rows=0 loops=1)
Index Cond: (id = 1)
Heap Fetches: 0
Buffers: shared hit=2
Planning:
Buffers: shared hit=15 read=7
Planning Time: 2.048 ms
Execution Time: 0.071 ms
(8 rows)

postgres=# alter index foo_pkey disable ;
ALTER INDEX
postgres=# explain analyze execute prp;
QUERY PLAN
-------------------------------------------------------------------------------------------------------------------
Index Only Scan using foo_pkey on foo (cost=0.15..8.17 rows=1
width=4) (actual time=0.035..0.036 rows=0 loops=1)
Index Cond: (id = 1)
Heap Fetches: 0
Buffers: shared hit=2
Planning Time: 0.012 ms
Execution Time: 0.320 ms
(6 rows)

Should this not behave like if you drop (or create) an index
during a prepared statement? I have not yet looked closely at
this code to see what could be done.

Regards,

Sami Imseih
Amazon Web Services (AWS)

[1]: https://www.postgresql.org/docs/current/catalogs.html

#52Michail Nikolaev
michail.nikolaev@gmail.com
In reply to: Shayon Mukherjee (#50)
Re: Proposal to Enable/Disable Index using ALTER INDEX (with patch)

Hello!

One more thing (maybe I missed it in the patch, but anyway) - should we
add some migration to ensure what old databases will get enabled=true by
default after upgrade?

Best regards,
Mikhail.

#53Sami Imseih
samimseih@gmail.com
In reply to: Michail Nikolaev (#52)
Re: Proposal to Enable/Disable Index using ALTER INDEX (with patch)

Should this not behave like if you drop (or create) an index
during a prepared statement? I have not yet looked closely at
this code to see what could be done.

Regards,

I looked at this a bit more and ATExecEnableDisableIndex
needs some tweaks.

What should be getting invalidated in the heap relation
that the index is on and not the index relation as it is in
the current patch.

You can retrieve the heap relation oid
IndexGetRelation(indexOid, false) and the
CacheInvalidateRelcache should be on the heap relation.

The planner needs to only care about the heap relation
invalidation to re-plan across multiple executions of
a prepared statement.

There should be a test for this scenario as well.

Regards,

Sami

#54Shayon Mukherjee
shayonj@gmail.com
In reply to: Sami Imseih (#51)
1 attachment(s)
Re: Proposal to Enable/Disable Index using ALTER INDEX (with patch)

On Mon, Dec 30, 2024 at 2:56 PM Sami Imseih <samimseih@gmail.com> wrote:

Rebased with the latest master as well.

Hi,

This is a great, long needed feature. Thanks for doing this.

I am late to this thread, but I took a look at the current patch
and have some comments as I continue to look.

Thank you so much for such detailed and useful feedback.

1/
instead of

+       If true, the index is currently enabled and should be used for
queries.
+       If false, the index is disabled and should not be used for queries,

how about?
....

It all makes sense to me. Thank you for the pointers to the docs and
existing practices as well. I have updated the patch accordingly.

"indisvalid" does not control constraint enforcement in this case. It will
be
"indisready" being set to false that will.

But even then, this goes against the general principle ( also documnted )
of not updating the catalog directly. See [1]

I think this part should be removed.

Makes sense and is fair. I also did not see examples of sharing queries in
the docs either. Updated the patch accordingly.

5/

In a case of a prepared statement, disabling the index
has no effect.

...

Should this not behave like if you drop (or create) an index

during a prepared statement? I have not yet looked closely at
this code to see what could be done.

oof! Great catch, can't believe I missed prepared statements 😅. I have
updated the patch to ensure we are invalidating the heap relation the index
is on from ATExecEnableDisableIndex and also backed it up with tests as
well. It should also address your feedback and suggestion in [1]/messages/by-id/CAA5RZ0sWpQZxjO9NEchwPeDbtw2HFWF-v8MscBDcm00FB6N_3w@mail.gmail.com

Thank you once again for the pointers and guidance. Attached v7 patch
(rebased with latest master).
Shayon

[1]: /messages/by-id/CAA5RZ0sWpQZxjO9NEchwPeDbtw2HFWF-v8MscBDcm00FB6N_3w@mail.gmail.com
/messages/by-id/CAA5RZ0sWpQZxjO9NEchwPeDbtw2HFWF-v8MscBDcm00FB6N_3w@mail.gmail.com

Attachments:

v7-0001-Introduce-the-ability-to-enable-disable-indexes-u.patchapplication/octet-stream; name=v7-0001-Introduce-the-ability-to-enable-disable-indexes-u.patchDownload
From 99ab5b6a7b0cf96451034c669f974f964e36d42f Mon Sep 17 00:00:00 2001
From: Shayon Mukherjee <shayonj@gmail.com>
Date: Thu, 17 Oct 2024 10:04:13 -0400
Subject: [PATCH v7] Introduce the ability to enable/disable indexes using
 ALTER INDEX

This patch introduces the ability to enable or disable indexes using ALTER INDEX
and CREATE INDEX commands.

Original motivation for the problem and proposal for a patch
can be found at [1].

This patch passes all the existing specs and the newly added regression tests. The patch
is ready for review and test. It compiles, so the can patch can be applied for testing as well.

Implementation details:

- New Grammar:
  * ALTER INDEX ... ENABLE/DISABLE
  * CREATE INDEX ... DISABLE

- Default state is enabled. Indexes are only disabled when explicitly
  instructed via CREATE INDEX ... DISABLE or ALTER INDEX ... DISABLE.

- Primary Key and Unique constraint indexes are always enabled as well. The
  ENABLE/DISABLE grammar is not supported for these types of indexes. They can
  be later disabled via ALTER INDEX ... ENABLE/DISABLE.

- ALTER INDEX ... ENABLE/DISABLE performs update on the relevant row in pg_index
  catalog

- pg_get_indexdef() support the new functionality and grammar. This change is
  reflected in \d output for tables and pg_dump. We show the DISABLE syntax accordingly.

- Updated create_index.sql regression test to cover the new grammar and verify
  that disabled indexes are not used in queries. The test CATALOG_VERSION_NO

  - Basic single-column and multi-column indexes
  - Partial indexes
  - Expression indexes
  - Join indexes
  - GIN and GiST indexes
  - Covering indexes
  - Range indexes
  - Unique indexes and constraints

- Adds a new enabled attribute to the IndexOptInfo structure.

- Modifies get_relation_info in plancat.c to skip disabled indexes entirely, thus reducing the number of places we need to check if an index is disabled or not. Inspired by the conversations start at [2].
  - I chose to modify the logic within get_relation_info as compared to, say, reducing the cost to make the planner not consider an index during planning, mostly to keep the number of changes being introduced to a minimum and also the logic itself being self-contained and easier to under perhaps (?).

- No changes are made to stop the index from getting rebuilt. This way we ensure no
  data miss or corruption when index is re-nabled.

- TOAST indexes are supported and enabled by default as well.

- REINDEX CONCURRENTLY is supported as well and existing state of pg_index.indisenabled
  is carried over accordingly.

- See the changes in create_index.sql to get an idea of the grammar and sql statements.

- See the changes in create_index.out to get an idea of the catalogue states and EXPLAIN
  output to see when an index is getting used or isn't (when disabled).

- Incorporated DavidR's feedback from [3] around documentation and also you will see that by skip disabled indexes entirely from get_relation_info in plancat.c (as mentioned above), we address the other mentioned issues as well.

- Lastly, protects against the case where indcheckxmin is true by raising ERRCODE_OBJECT_NOT_IN_PREREQUISITE_STATE.

Looking forward to any and all feedback on this patch, including but not limited to code quality, tests, fundamental logic.

[1] https://www.postgresql.org/message-id/CANqtF-oXKe0M%3D0QOih6H%2BsZRjE2BWAbkW_1%2B9nMEAMLxUJg5jA%40mail.gmail.com
[2] https://www.postgresql.org/message-id/3465209.1727202064%40sss.pgh.pa.us
[3] https://www.postgresql.org/message-id/CAApHDvpUNu%3DiVcdJ74sypvgeaCF%2Btfpyb8VRhZaF7DTd1xVr7g%40mail.gmail.com
---
 doc/src/sgml/catalogs.sgml                 |  11 +
 doc/src/sgml/ref/alter_index.sgml          |  42 ++
 doc/src/sgml/ref/create_index.sgml         |  29 ++
 src/backend/bootstrap/bootparse.y          |   2 +
 src/backend/catalog/index.c                |  31 +-
 src/backend/catalog/toasting.c             |   2 +-
 src/backend/commands/indexcmds.c           |   4 +
 src/backend/commands/tablecmds.c           |  72 ++-
 src/backend/optimizer/util/plancat.c       |  11 +-
 src/backend/parser/gram.y                  |  48 +-
 src/backend/parser/parse_utilcmd.c         |   3 +
 src/backend/utils/adt/ruleutils.c          |   4 +
 src/backend/utils/cache/relcache.c         |   1 +
 src/include/catalog/index.h                |   2 +-
 src/include/catalog/pg_index.h             |   1 +
 src/include/nodes/parsenodes.h             |   3 +
 src/include/nodes/pathnodes.h              |   2 +
 src/test/regress/expected/create_index.out | 560 +++++++++++++++++++++
 src/test/regress/sql/create_index.sql      | 214 ++++++++
 19 files changed, 1026 insertions(+), 16 deletions(-)

diff --git a/doc/src/sgml/catalogs.sgml b/doc/src/sgml/catalogs.sgml
index cc6cf9bef0..1d579add4e 100644
--- a/doc/src/sgml/catalogs.sgml
+++ b/doc/src/sgml/catalogs.sgml
@@ -4585,6 +4585,17 @@ SCRAM-SHA-256$<replaceable>&lt;iteration count&gt;</replaceable>:<replaceable>&l
        partial index.
       </para></entry>
      </row>
+
+     <row>
+      <entry role="catalog_table_entry"><para role="column_definition">
+       <structfield>indisenabled</structfield> <type>bool</type>
+      </para>
+      <para>
+       If true, the index is currently enabled and may be used for queries.
+       If false, the index is disabled and may not be used for queries,
+       but is still updated when the table is modified. Default is true.
+      </para></entry>
+     </row>
     </tbody>
    </tgroup>
   </table>
diff --git a/doc/src/sgml/ref/alter_index.sgml b/doc/src/sgml/ref/alter_index.sgml
index 1d42d05d85..8fb1517fa8 100644
--- a/doc/src/sgml/ref/alter_index.sgml
+++ b/doc/src/sgml/ref/alter_index.sgml
@@ -31,6 +31,8 @@ ALTER INDEX [ IF EXISTS ] <replaceable class="parameter">name</replaceable> ALTE
     SET STATISTICS <replaceable class="parameter">integer</replaceable>
 ALTER INDEX ALL IN TABLESPACE <replaceable class="parameter">name</replaceable> [ OWNED BY <replaceable class="parameter">role_name</replaceable> [, ... ] ]
     SET TABLESPACE <replaceable class="parameter">new_tablespace</replaceable> [ NOWAIT ]
+ALTER INDEX [ IF EXISTS ] <replaceable class="parameter">name</replaceable> ENABLE
+ALTER INDEX [ IF EXISTS ] <replaceable class="parameter">name</replaceable> DISABLE
 </synopsis>
  </refsynopsisdiv>
 
@@ -159,6 +161,32 @@ ALTER INDEX ALL IN TABLESPACE <replaceable class="parameter">name</replaceable>
     </listitem>
    </varlistentry>
 
+   <varlistentry>
+    <term><literal>ENABLE</literal></term>
+    <listitem>
+     <para>
+      Enable the specified index. The index will be used for queries. This is the
+      default state for newly created indexes.
+     </para>
+    </listitem>
+   </varlistentry>
+
+   <varlistentry>
+    <term><literal>DISABLE</literal></term>
+    <listitem>
+     <para>
+      Disable the specified index. A disabled index is not used for queries, but it
+      is still updated when the underlying table data changes and will still be
+      used to enforce constraints (such as UNIQUE, or PRIMARY KEY constraints).
+      This can be useful for testing query performance with and without specific
+      indexes. If performance degrades after disabling an index, it can be easily
+      re-enabled using <literal>ENABLE</literal>. Before disabling, it's recommended
+      to check <structname>pg_stat_user_indexes</structname>.<structfield>idx_scan</structfield>
+      to identify potentially unused indexes.
+     </para>
+    </listitem>
+   </varlistentry>
+
   </variablelist>
   </para>
 
@@ -301,6 +329,20 @@ CREATE INDEX coord_idx ON measured (x, y, (z + t));
 ALTER INDEX coord_idx ALTER COLUMN 3 SET STATISTICS 1000;
 </programlisting></para>
 
+  <para>
+   To enable an index:
+<programlisting>
+ALTER INDEX idx_name ENABLE;
+</programlisting>
+  </para>
+
+  <para>
+   To disable an index:
+<programlisting>
+ALTER INDEX idx_name DISABLE;
+</programlisting>
+  </para>
+
  </refsect1>
 
  <refsect1>
diff --git a/doc/src/sgml/ref/create_index.sgml b/doc/src/sgml/ref/create_index.sgml
index 208389e800..a769311285 100644
--- a/doc/src/sgml/ref/create_index.sgml
+++ b/doc/src/sgml/ref/create_index.sgml
@@ -28,6 +28,7 @@ CREATE [ UNIQUE ] INDEX [ CONCURRENTLY ] [ [ IF NOT EXISTS ] <replaceable class=
     [ WITH ( <replaceable class="parameter">storage_parameter</replaceable> [= <replaceable class="parameter">value</replaceable>] [, ... ] ) ]
     [ TABLESPACE <replaceable class="parameter">tablespace_name</replaceable> ]
     [ WHERE <replaceable class="parameter">predicate</replaceable> ]
+    [ DISABLE ]
 </synopsis>
  </refsynopsisdiv>
 
@@ -380,6 +381,19 @@ CREATE [ UNIQUE ] INDEX [ CONCURRENTLY ] [ [ IF NOT EXISTS ] <replaceable class=
       </listitem>
      </varlistentry>
 
+    <varlistentry>
+      <term><literal>DISABLE</literal></term>
+      <listitem>
+       <para>
+        Creates the index in a disabled state (default enabled). A disabled index is not used by the
+        query planner for query optimization, but it is still maintained when the
+        underlying table data changes. This can be useful when you want to create
+        an index without immediately impacting query performance, allowing you to
+        enable it later at a more convenient time. The index can be enabled later
+        using <command>ALTER INDEX ... ENABLE</command>.
+       </para>
+      </listitem>
+     </varlistentry>
     </variablelist>
 
   <refsect2 id="sql-createindex-storage-parameters" xreflabel="Index Storage Parameters">
@@ -701,6 +715,14 @@ Indexes:
     partitioned index is a metadata only operation.
    </para>
 
+  <para>
+   When creating an index with the <literal>DISABLE</literal> option, the index
+   will be created but not used for query planning. This can be useful for
+   preparing an index in advance of its use, or for testing purposes. The index
+   will still be maintained as the table is modified, so it can be enabled
+   later without needing to be rebuilt. By default all new indexes are enabled.
+  </para>
+
   </refsect2>
  </refsect1>
 
@@ -980,6 +1002,13 @@ SELECT * FROM points
 CREATE INDEX CONCURRENTLY sales_quantity_index ON sales_table (quantity);
 </programlisting></para>
 
+  <para>
+   To create an index on the table <literal>test_table</literal> with the default
+   name, but have it initially disabled:
+<programlisting>
+CREATE INDEX ON test_table (col1) DISABLE;
+</programlisting>
+  </para>
  </refsect1>
 
  <refsect1>
diff --git a/src/backend/bootstrap/bootparse.y b/src/backend/bootstrap/bootparse.y
index 05ef26c07d..ba2e738172 100644
--- a/src/backend/bootstrap/bootparse.y
+++ b/src/backend/bootstrap/bootparse.y
@@ -303,6 +303,7 @@ Boot_DeclareIndexStmt:
 					stmt->concurrent = false;
 					stmt->if_not_exists = false;
 					stmt->reset_default_tblspc = false;
+					stmt->isenabled = true;
 
 					/* locks and races need not concern us in bootstrap mode */
 					relationId = RangeVarGetRelid(stmt->relation, NoLock,
@@ -356,6 +357,7 @@ Boot_DeclareUniqueIndexStmt:
 					stmt->concurrent = false;
 					stmt->if_not_exists = false;
 					stmt->reset_default_tblspc = false;
+					stmt->isenabled = true;
 
 					/* locks and races need not concern us in bootstrap mode */
 					relationId = RangeVarGetRelid(stmt->relation, NoLock,
diff --git a/src/backend/catalog/index.c b/src/backend/catalog/index.c
index 6976249e9e..e4ab05e902 100644
--- a/src/backend/catalog/index.c
+++ b/src/backend/catalog/index.c
@@ -118,7 +118,8 @@ static void UpdateIndexRelation(Oid indexoid, Oid heapoid,
 								bool isexclusion,
 								bool immediate,
 								bool isvalid,
-								bool isready);
+								bool isready,
+								bool isenabled);
 static void index_update_stats(Relation rel,
 							   bool hasindex,
 							   double reltuples);
@@ -570,7 +571,8 @@ UpdateIndexRelation(Oid indexoid,
 					bool isexclusion,
 					bool immediate,
 					bool isvalid,
-					bool isready)
+					bool isready,
+					bool isenabled)
 {
 	int2vector *indkey;
 	oidvector  *indcollation;
@@ -648,6 +650,7 @@ UpdateIndexRelation(Oid indexoid,
 	values[Anum_pg_index_indisready - 1] = BoolGetDatum(isready);
 	values[Anum_pg_index_indislive - 1] = BoolGetDatum(true);
 	values[Anum_pg_index_indisreplident - 1] = BoolGetDatum(false);
+	values[Anum_pg_index_indisenabled - 1] = BoolGetDatum(isenabled);
 	values[Anum_pg_index_indkey - 1] = PointerGetDatum(indkey);
 	values[Anum_pg_index_indcollation - 1] = PointerGetDatum(indcollation);
 	values[Anum_pg_index_indclass - 1] = PointerGetDatum(indclass);
@@ -713,6 +716,8 @@ UpdateIndexRelation(Oid indexoid,
  *			already exists.
  *		INDEX_CREATE_PARTITIONED:
  *			create a partitioned index (table must be partitioned)
+ *		INDEX_CREATE_DISABLED:
+*				create the index as disabled if instructed, defaults to being enabled.
  * constr_flags: flags passed to index_constraint_create
  *		(only if INDEX_CREATE_ADD_CONSTRAINT is set)
  * allow_system_table_mods: allow table to be a system catalog
@@ -758,6 +763,7 @@ index_create(Relation heapRelation,
 	bool		invalid = (flags & INDEX_CREATE_INVALID) != 0;
 	bool		concurrent = (flags & INDEX_CREATE_CONCURRENT) != 0;
 	bool		partitioned = (flags & INDEX_CREATE_PARTITIONED) != 0;
+	bool 		isenabled  = (flags & INDEX_CREATE_ENABLED) != 0;
 	char		relkind;
 	TransactionId relfrozenxid;
 	MultiXactId relminmxid;
@@ -1041,13 +1047,15 @@ index_create(Relation heapRelation,
 	 *	  (Or, could define a rule to maintain the predicate) --Nels, Feb '92
 	 * ----------------
 	 */
+
 	UpdateIndexRelation(indexRelationId, heapRelationId, parentIndexRelid,
 						indexInfo,
 						collationIds, opclassIds, coloptions,
 						isprimary, is_exclusion,
 						(constr_flags & INDEX_CONSTR_CREATE_DEFERRABLE) == 0,
 						!concurrent && !invalid,
-						!concurrent);
+						!concurrent,
+						isenabled);
 
 	/*
 	 * Register relcache invalidation on the indexes' heap relation, to
@@ -1316,6 +1324,8 @@ index_concurrently_create_copy(Relation heapRelation, Oid oldIndexId,
 	List	   *indexColNames = NIL;
 	List	   *indexExprs = NIL;
 	List	   *indexPreds = NIL;
+	Form_pg_index indexForm;
+	bits16 	 createFlags;
 
 	indexRelation = index_open(oldIndexId, RowExclusiveLock);
 
@@ -1343,6 +1353,9 @@ index_concurrently_create_copy(Relation heapRelation, Oid oldIndexId,
 											Anum_pg_index_indoption);
 	indcoloptions = (int2vector *) DatumGetPointer(colOptionDatum);
 
+	/* Get the enabled state of the original index */
+	indexForm = (Form_pg_index) GETSTRUCT(indexTuple);
+
 	/* Fetch reloptions of index if any */
 	classTuple = SearchSysCache1(RELOID, ObjectIdGetDatum(oldIndexId));
 	if (!HeapTupleIsValid(classTuple))
@@ -1434,6 +1447,16 @@ index_concurrently_create_copy(Relation heapRelation, Oid oldIndexId,
 		stattargets[i].isnull = isnull;
 	}
 
+	/*
+	* Determine the create flags for the new index.
+	* We always use SKIP_BUILD and CONCURRENT for concurrent reindexing.
+	* If the original index was enabled, we also set the ENABLED flag
+	* to maintain the same state in the new index.
+	*/
+	createFlags = INDEX_CREATE_SKIP_BUILD | INDEX_CREATE_CONCURRENT;
+	if (indexForm->indisenabled)
+			createFlags |= INDEX_CREATE_ENABLED;
+
 	/*
 	 * Now create the new index.
 	 *
@@ -1457,7 +1480,7 @@ index_concurrently_create_copy(Relation heapRelation, Oid oldIndexId,
 							  indcoloptions->values,
 							  stattargets,
 							  reloptionsDatum,
-							  INDEX_CREATE_SKIP_BUILD | INDEX_CREATE_CONCURRENT,
+							  createFlags,
 							  0,
 							  true, /* allow table to be a system catalog? */
 							  false,	/* is_internal? */
diff --git a/src/backend/catalog/toasting.c b/src/backend/catalog/toasting.c
index ad3082c62a..dead993a74 100644
--- a/src/backend/catalog/toasting.c
+++ b/src/backend/catalog/toasting.c
@@ -325,7 +325,7 @@ create_toast_table(Relation rel, Oid toastOid, Oid toastIndexOid,
 				 BTREE_AM_OID,
 				 rel->rd_rel->reltablespace,
 				 collationIds, opclassIds, NULL, coloptions, NULL, (Datum) 0,
-				 INDEX_CREATE_IS_PRIMARY, 0, true, true, NULL);
+				 INDEX_CREATE_IS_PRIMARY | INDEX_CREATE_ENABLED, 0, true, true, NULL);
 
 	table_close(toast_rel, NoLock);
 
diff --git a/src/backend/commands/indexcmds.c b/src/backend/commands/indexcmds.c
index 4049ce1a10..b456069f94 100644
--- a/src/backend/commands/indexcmds.c
+++ b/src/backend/commands/indexcmds.c
@@ -1198,6 +1198,10 @@ DefineIndex(Oid tableId,
 		flags |= INDEX_CREATE_PARTITIONED;
 	if (stmt->primary)
 		flags |= INDEX_CREATE_IS_PRIMARY;
+   if (stmt->isenabled)
+		flags |= INDEX_CREATE_ENABLED;
+   else
+		flags &= ~INDEX_CREATE_ENABLED;
 
 	/*
 	 * If the table is partitioned, and recursion was declined but partitions
diff --git a/src/backend/commands/tablecmds.c b/src/backend/commands/tablecmds.c
index 4937478262..064032f771 100644
--- a/src/backend/commands/tablecmds.c
+++ b/src/backend/commands/tablecmds.c
@@ -688,7 +688,7 @@ static List *GetParentedForeignKeyRefs(Relation partition);
 static void ATDetachCheckNoForeignKeyRefs(Relation partition);
 static char GetAttributeCompression(Oid atttypid, const char *compression);
 static char GetAttributeStorage(Oid atttypid, const char *storagemode);
-
+static void ATExecEnableDisableIndex(Relation rel, bool enable);
 
 /* ----------------------------------------------------------------
  *		DefineRelation
@@ -4632,6 +4632,8 @@ AlterTableGetLockLevel(List *cmds)
 			case AT_SetExpression:
 			case AT_DropExpression:
 			case AT_SetCompression:
+			case AT_EnableIndex:
+			case AT_DisableIndex:
 				cmd_lockmode = AccessExclusiveLock;
 				break;
 
@@ -5194,6 +5196,12 @@ ATPrepCmd(List **wqueue, Relation rel, AlterTableCmd *cmd,
 			/* No command-specific prep needed */
 			pass = AT_PASS_MISC;
 			break;
+		case AT_EnableIndex:
+		case AT_DisableIndex:
+			ATSimplePermissions(cmd->subtype, rel, ATT_INDEX | ATT_PARTITIONED_INDEX);
+			/* No command-specific prep needed */
+			pass = AT_PASS_MISC;
+			break;
 		default:				/* oops */
 			elog(ERROR, "unrecognized alter table type: %d",
 				 (int) cmd->subtype);
@@ -5588,6 +5596,12 @@ ATExecCmd(List **wqueue, AlteredTableInfo *tab,
 		case AT_DetachPartitionFinalize:
 			address = ATExecDetachPartitionFinalize(rel, ((PartitionCmd *) cmd->def)->name);
 			break;
+		case AT_EnableIndex:
+				ATExecEnableDisableIndex(rel, true);
+				break;
+		case AT_DisableIndex:
+				ATExecEnableDisableIndex(rel, false);
+				break;
 		default:				/* oops */
 			elog(ERROR, "unrecognized alter table type: %d",
 				 (int) cmd->subtype);
@@ -6477,6 +6491,8 @@ alter_table_type_to_string(AlterTableType cmdtype)
 			return "DROP COLUMN";
 		case AT_AddIndex:
 		case AT_ReAddIndex:
+		case AT_EnableIndex:
+		case AT_DisableIndex:
 			return NULL;		/* not real grammar */
 		case AT_AddConstraint:
 		case AT_ReAddConstraint:
@@ -20812,3 +20828,57 @@ GetAttributeStorage(Oid atttypid, const char *storagemode)
 
 	return cstorage;
 }
+
+/*
+ * ATExecEnableDisableIndex
+ * Performs a catalog update to enable or disable an index in pg_index.
+ */
+static void
+ATExecEnableDisableIndex(Relation rel, bool enable)
+{
+	Oid         indexOid = RelationGetRelid(rel);
+	Oid         heapOid;
+	Relation    pg_index;
+	HeapTuple   indexTuple;
+	Form_pg_index indexForm;
+	bool        updated = false;
+	Relation    heapRel;
+
+	pg_index = table_open(IndexRelationId, RowExclusiveLock);
+
+	indexTuple = SearchSysCacheCopy1(INDEXRELID, ObjectIdGetDatum(indexOid));
+	if (!HeapTupleIsValid(indexTuple))
+		elog(ERROR, "could not find tuple for index %u", indexOid);
+
+	indexForm = (Form_pg_index) GETSTRUCT(indexTuple);
+	if (indexForm->indcheckxmin)
+	{
+		heap_freetuple(indexTuple);
+		table_close(pg_index, RowExclusiveLock);
+		ereport(ERROR,
+				(errcode(ERRCODE_OBJECT_NOT_IN_PREREQUISITE_STATE),
+				errmsg("cannot enable/disable index while indcheckxmin is true"),
+				errhint("Wait for all transactions that might see inconsistent HOT chains to complete")));
+	}
+
+	if (indexForm->indisenabled != enable)
+	{
+		indexForm->indisenabled = enable;
+
+		CatalogTupleUpdate(pg_index, &indexTuple->t_self, indexTuple);
+		updated = true;
+	}
+
+	heap_freetuple(indexTuple);
+	table_close(pg_index, RowExclusiveLock);
+
+	if (updated)
+	{
+		heapOid = IndexGetRelation(indexOid, false);
+		heapRel = table_open(heapOid, AccessShareLock);
+		CacheInvalidateRelcache(heapRel);
+		table_close(heapRel, AccessShareLock);
+		InvokeObjectPostAlterHook(IndexRelationId, indexOid, 0);
+		CommandCounterIncrement();
+	}
+}
diff --git a/src/backend/optimizer/util/plancat.c b/src/backend/optimizer/util/plancat.c
index c31cc3ee69..f66e49d94e 100644
--- a/src/backend/optimizer/util/plancat.c
+++ b/src/backend/optimizer/util/plancat.c
@@ -254,13 +254,12 @@ get_relation_info(PlannerInfo *root, Oid relationObjectId, bool inhparent,
 			index = indexRelation->rd_index;
 
 			/*
-			 * Ignore invalid indexes, since they can't safely be used for
-			 * queries.  Note that this is OK because the data structure we
-			 * are constructing is only used by the planner --- the executor
-			 * still needs to insert into "invalid" indexes, if they're marked
-			 * indisready.
+			 * Ignore invalid or disabled indexes, since they can't safely be used for
+			 * queries. This is OK because the data structure we are constructing is
+			 * only used by the planner - the executor still needs to insert into
+			 * "invalid" indexes if they're marked indisready.
 			 */
-			if (!index->indisvalid)
+			if (!index->indisvalid || !index->indisenabled)
 			{
 				index_close(indexRelation, NoLock);
 				continue;
diff --git a/src/backend/parser/gram.y b/src/backend/parser/gram.y
index bd5ebb35c4..64749b9b4f 100644
--- a/src/backend/parser/gram.y
+++ b/src/backend/parser/gram.y
@@ -320,7 +320,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 %type <ival>	add_drop opt_asc_desc opt_nulls_order
 
 %type <node>	alter_table_cmd alter_type_cmd opt_collate_clause
-	   replica_identity partition_cmd index_partition_cmd
+	   replica_identity partition_cmd index_partition_cmd index_alter_cmd
 %type <list>	alter_table_cmds alter_type_cmds
 %type <list>    alter_identity_column_option_list
 %type <defelt>  alter_identity_column_option
@@ -483,6 +483,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 %type <boolean> opt_unique opt_verbose opt_full
 %type <boolean> opt_freeze opt_analyze opt_default
 %type <defelt>	opt_binary copy_delimiter
+%type <boolean>  opt_index_enabled
 
 %type <boolean> copy_from opt_program
 
@@ -2149,6 +2150,24 @@ AlterTableStmt:
 					n->nowait = $13;
 					$$ = (Node *) n;
 				}
+		| ALTER INDEX qualified_name index_alter_cmd
+				{
+					AlterTableStmt *n = makeNode(AlterTableStmt);
+					n->relation = $3;
+					n->cmds = list_make1($4);
+					n->objtype = OBJECT_INDEX;
+					n->missing_ok = false;
+					$$ = (Node *) n;
+				}
+		| ALTER INDEX IF_P EXISTS qualified_name index_alter_cmd
+				{
+					AlterTableStmt *n = makeNode(AlterTableStmt);
+					n->relation = $5;
+					n->cmds = list_make1($6);
+					n->objtype = OBJECT_INDEX;
+					n->missing_ok = true;
+					$$ = (Node *) n;
+				}
 		|	ALTER INDEX qualified_name alter_table_cmds
 				{
 					AlterTableStmt *n = makeNode(AlterTableStmt);
@@ -2374,6 +2393,21 @@ index_partition_cmd:
 				}
 		;
 
+index_alter_cmd:
+		/* ALTER INDEX <name> ENABLE|DISABLE */
+		ENABLE_P
+			{
+				AlterTableCmd *n = makeNode(AlterTableCmd);
+				n->subtype = AT_EnableIndex;
+				$$ = (Node *) n;
+			}
+		| DISABLE_P
+			{
+				AlterTableCmd *n = makeNode(AlterTableCmd);
+				n->subtype = AT_DisableIndex;
+				$$ = (Node *) n;
+			}
+		;
 alter_table_cmd:
 			/* ALTER TABLE <name> ADD <coldef> */
 			ADD_P columnDef
@@ -8129,7 +8163,7 @@ defacl_privilege_target:
 
 IndexStmt:	CREATE opt_unique INDEX opt_concurrently opt_single_name
 			ON relation_expr access_method_clause '(' index_params ')'
-			opt_include opt_unique_null_treatment opt_reloptions OptTableSpace where_clause
+			opt_include opt_unique_null_treatment opt_reloptions OptTableSpace where_clause opt_index_enabled
 				{
 					IndexStmt *n = makeNode(IndexStmt);
 
@@ -8144,6 +8178,7 @@ IndexStmt:	CREATE opt_unique INDEX opt_concurrently opt_single_name
 					n->options = $14;
 					n->tableSpace = $15;
 					n->whereClause = $16;
+					n->isenabled = $17;
 					n->excludeOpNames = NIL;
 					n->idxcomment = NULL;
 					n->indexOid = InvalidOid;
@@ -8161,7 +8196,7 @@ IndexStmt:	CREATE opt_unique INDEX opt_concurrently opt_single_name
 				}
 			| CREATE opt_unique INDEX opt_concurrently IF_P NOT EXISTS name
 			ON relation_expr access_method_clause '(' index_params ')'
-			opt_include opt_unique_null_treatment opt_reloptions OptTableSpace where_clause
+			opt_include opt_unique_null_treatment opt_reloptions OptTableSpace where_clause opt_index_enabled
 				{
 					IndexStmt *n = makeNode(IndexStmt);
 
@@ -8176,6 +8211,7 @@ IndexStmt:	CREATE opt_unique INDEX opt_concurrently opt_single_name
 					n->options = $17;
 					n->tableSpace = $18;
 					n->whereClause = $19;
+					n->isenabled = $20;
 					n->excludeOpNames = NIL;
 					n->idxcomment = NULL;
 					n->indexOid = InvalidOid;
@@ -8198,6 +8234,12 @@ opt_unique:
 			| /*EMPTY*/								{ $$ = false; }
 		;
 
+opt_index_enabled:
+			ENABLE_P                      { $$ = true; }
+			| DISABLE_P                   { $$ = false; }
+			| /*EMPTY*/                 	{ $$ = true; }
+		;
+
 access_method_clause:
 			USING name								{ $$ = $2; }
 			| /*EMPTY*/								{ $$ = DEFAULT_INDEX_TYPE; }
diff --git a/src/backend/parser/parse_utilcmd.c b/src/backend/parser/parse_utilcmd.c
index 95dad76683..41a8e57f3d 100644
--- a/src/backend/parser/parse_utilcmd.c
+++ b/src/backend/parser/parse_utilcmd.c
@@ -1736,6 +1736,7 @@ generateClonedIndexStmt(RangeVar *heapRel, Relation source_idx,
 	index->concurrent = false;
 	index->if_not_exists = false;
 	index->reset_default_tblspc = false;
+	index->isenabled = idxrec->indisenabled;
 
 	/*
 	 * We don't try to preserve the name of the source index; instead, just
@@ -2357,6 +2358,8 @@ transformIndexConstraint(Constraint *constraint, CreateStmtContext *cxt)
 	index->concurrent = false;
 	index->if_not_exists = false;
 	index->reset_default_tblspc = constraint->reset_default_tblspc;
+	/* Ensure indexes for constraints are created as enabled by default */
+	index->isenabled = true;
 
 	/*
 	 * If it's ALTER TABLE ADD CONSTRAINT USING INDEX, look up the index and
diff --git a/src/backend/utils/adt/ruleutils.c b/src/backend/utils/adt/ruleutils.c
index be1f1f50b7..2c403a08fe 100644
--- a/src/backend/utils/adt/ruleutils.c
+++ b/src/backend/utils/adt/ruleutils.c
@@ -1559,6 +1559,10 @@ pg_get_indexdef_worker(Oid indexrelid, int colno,
 			else
 				appendStringInfo(&buf, " WHERE %s", str);
 		}
+
+		/* Add DISABLE clause if the index is disabled */
+		if (!idxrec->indisenabled)
+				appendStringInfoString(&buf, " DISABLE");
 	}
 
 	/* Clean up */
diff --git a/src/backend/utils/cache/relcache.c b/src/backend/utils/cache/relcache.c
index 1ce7eb9da8..e343c6916f 100644
--- a/src/backend/utils/cache/relcache.c
+++ b/src/backend/utils/cache/relcache.c
@@ -2311,6 +2311,7 @@ RelationReloadIndexInfo(Relation relation)
 		relation->rd_index->indisready = index->indisready;
 		relation->rd_index->indislive = index->indislive;
 		relation->rd_index->indisreplident = index->indisreplident;
+		relation->rd_index->indisenabled = index->indisenabled;
 
 		/* Copy xmin too, as that is needed to make sense of indcheckxmin */
 		HeapTupleHeaderSetXmin(relation->rd_indextuple->t_data,
diff --git a/src/include/catalog/index.h b/src/include/catalog/index.h
index 2dea96f47c..8a47cfd174 100644
--- a/src/include/catalog/index.h
+++ b/src/include/catalog/index.h
@@ -65,6 +65,7 @@ extern void index_check_primary_key(Relation heapRel,
 #define	INDEX_CREATE_IF_NOT_EXISTS			(1 << 4)
 #define	INDEX_CREATE_PARTITIONED			(1 << 5)
 #define INDEX_CREATE_INVALID				(1 << 6)
+#define INDEX_CREATE_ENABLED        (1 << 7)
 
 extern Oid	index_create(Relation heapRelation,
 						 const char *indexRelationName,
@@ -175,7 +176,6 @@ extern void RestoreReindexState(const void *reindexstate);
 
 extern void IndexSetParentIndex(Relation partitionIdx, Oid parentOid);
 
-
 /*
  * itemptr_encode - Encode ItemPointer as int64/int8
  *
diff --git a/src/include/catalog/pg_index.h b/src/include/catalog/pg_index.h
index 6c89639a9e..a6d715d260 100644
--- a/src/include/catalog/pg_index.h
+++ b/src/include/catalog/pg_index.h
@@ -44,6 +44,7 @@ CATALOG(pg_index,2610,IndexRelationId) BKI_SCHEMA_MACRO
 	bool		indisready;		/* is this index ready for inserts? */
 	bool		indislive;		/* is this index alive at all? */
 	bool		indisreplident; /* is this index the identity for replication? */
+	bool		indisenabled BKI_DEFAULT(t);	/* is this index enabled for use by queries? */
 
 	/* variable-length fields start here, but we allow direct access to indkey */
 	int2vector	indkey BKI_FORCE_NOT_NULL;	/* column numbers of indexed cols,
diff --git a/src/include/nodes/parsenodes.h b/src/include/nodes/parsenodes.h
index 0f9462493e..5054f9f8bb 100644
--- a/src/include/nodes/parsenodes.h
+++ b/src/include/nodes/parsenodes.h
@@ -2423,6 +2423,8 @@ typedef enum AlterTableType
 	AT_SetIdentity,				/* SET identity column options */
 	AT_DropIdentity,			/* DROP IDENTITY */
 	AT_ReAddStatistics,			/* internal to commands/tablecmds.c */
+	AT_EnableIndex,					/* ENABLE INDEX */
+	AT_DisableIndex,				/* DISABLE INDEX */
 } AlterTableType;
 
 typedef struct ReplicaIdentityStmt
@@ -3402,6 +3404,7 @@ typedef struct IndexStmt
 	bool		if_not_exists;	/* just do nothing if index already exists? */
 	bool		reset_default_tblspc;	/* reset default_tablespace prior to
 										 * executing */
+  bool		isenabled;		/* true if ENABLE (default), false if DISABLE */
 } IndexStmt;
 
 /* ----------------------
diff --git a/src/include/nodes/pathnodes.h b/src/include/nodes/pathnodes.h
index 58748d2ca6..be77186c87 100644
--- a/src/include/nodes/pathnodes.h
+++ b/src/include/nodes/pathnodes.h
@@ -1212,6 +1212,8 @@ struct IndexOptInfo
 	/* AM's cost estimator */
 	/* Rather than include amapi.h here, we declare amcostestimate like this */
 	void		(*amcostestimate) (struct PlannerInfo *, struct IndexPath *, double, Cost *, Cost *, Selectivity *, double *, double *) pg_node_attr(read_write_ignore);
+	/* true if this index is enabled */
+	bool		enabled;
 };
 
 /*
diff --git a/src/test/regress/expected/create_index.out b/src/test/regress/expected/create_index.out
index 1904eb65bb..958b62adfe 100644
--- a/src/test/regress/expected/create_index.out
+++ b/src/test/regress/expected/create_index.out
@@ -3318,6 +3318,566 @@ ERROR:  REINDEX SCHEMA cannot run inside a transaction block
 END;
 -- concurrently
 REINDEX SCHEMA CONCURRENTLY schema_to_reindex;
+-- Test enable/disable functionality for indexes
+CREATE TABLE index_test(
+    id INT PRIMARY KEY,
+    data TEXT,
+    num INT,
+    vector INT[],
+    range INT4RANGE
+);
+INSERT INTO index_test
+SELECT
+    g,
+    'data ' || g,
+    g % 100,
+    ARRAY[g, g+1, g+2],
+    int4range(g, g+10)
+FROM generate_series(1, 1000) g;
+-- Function for testing
+CREATE FUNCTION get_data_length(text) RETURNS INT AS $$
+    SELECT length($1);
+$$ LANGUAGE SQL IMMUTABLE;
+-- Helper function to show index status
+CREATE OR REPLACE FUNCTION show_index_status(index_name text)
+RETURNS TABLE (
+    indexrelid regclass,
+    indisvalid boolean,
+    indisready boolean,
+    indislive boolean,
+    indisenabled boolean
+) AS $$
+BEGIN
+    RETURN QUERY EXECUTE format('
+        SELECT indexrelid::regclass, indisvalid, indisready, indislive, indisenabled
+        FROM pg_index
+        WHERE indexrelid = %L::regclass', index_name);
+END;
+$$ LANGUAGE plpgsql;
+-- Create and test each index type
+-- 1. Basic single-column index
+CREATE INDEX idx_single ON index_test(data);
+SELECT show_index_status('idx_single');
+  show_index_status   
+----------------------
+ (idx_single,t,t,t,t)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE data = 'data 500';
+                  QUERY PLAN                   
+-----------------------------------------------
+ Bitmap Heap Scan on index_test
+   Recheck Cond: (data = 'data 500'::text)
+   ->  Bitmap Index Scan on idx_single
+         Index Cond: (data = 'data 500'::text)
+(4 rows)
+
+ALTER INDEX idx_single DISABLE;
+SELECT show_index_status('idx_single');
+  show_index_status   
+----------------------
+ (idx_single,t,t,t,f)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE data = 'data 500';
+             QUERY PLAN              
+-------------------------------------
+ Seq Scan on index_test
+   Filter: (data = 'data 500'::text)
+(2 rows)
+
+ALTER INDEX idx_single ENABLE;
+SELECT show_index_status('idx_single');
+  show_index_status   
+----------------------
+ (idx_single,t,t,t,t)
+(1 row)
+
+-- 2. Multi-column index
+CREATE INDEX idx_multi ON index_test(num, data);
+SELECT show_index_status('idx_multi');
+  show_index_status  
+---------------------
+ (idx_multi,t,t,t,t)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE num = 50 AND data > 'data 500';
+                           QUERY PLAN                           
+----------------------------------------------------------------
+ Bitmap Heap Scan on index_test
+   Recheck Cond: ((num = 50) AND (data > 'data 500'::text))
+   ->  Bitmap Index Scan on idx_multi
+         Index Cond: ((num = 50) AND (data > 'data 500'::text))
+(4 rows)
+
+ALTER INDEX idx_multi DISABLE;
+SELECT show_index_status('idx_multi');
+  show_index_status  
+---------------------
+ (idx_multi,t,t,t,f)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE num = 50 AND data > 'data 500';
+                      QUERY PLAN                      
+------------------------------------------------------
+ Seq Scan on index_test
+   Filter: ((data > 'data 500'::text) AND (num = 50))
+(2 rows)
+
+ALTER INDEX idx_multi ENABLE;
+SELECT show_index_status('idx_multi');
+  show_index_status  
+---------------------
+ (idx_multi,t,t,t,t)
+(1 row)
+
+-- 3. Partial index
+CREATE INDEX idx_partial ON index_test(num) WHERE num < 50;
+SELECT show_index_status('idx_partial');
+   show_index_status   
+-----------------------
+ (idx_partial,t,t,t,t)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE num = 25;
+               QUERY PLAN               
+----------------------------------------
+ Bitmap Heap Scan on index_test
+   Recheck Cond: (num = 25)
+   ->  Bitmap Index Scan on idx_partial
+         Index Cond: (num = 25)
+(4 rows)
+
+ALTER INDEX idx_partial DISABLE;
+SELECT show_index_status('idx_partial');
+   show_index_status   
+-----------------------
+ (idx_partial,t,t,t,f)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE num = 25;
+              QUERY PLAN              
+--------------------------------------
+ Bitmap Heap Scan on index_test
+   Recheck Cond: (num = 25)
+   ->  Bitmap Index Scan on idx_multi
+         Index Cond: (num = 25)
+(4 rows)
+
+ALTER INDEX idx_partial ENABLE;
+SELECT show_index_status('idx_partial');
+   show_index_status   
+-----------------------
+ (idx_partial,t,t,t,t)
+(1 row)
+
+-- 4. Expression index
+CREATE INDEX idx_expression ON index_test((lower(data)));
+SELECT show_index_status('idx_expression');
+    show_index_status     
+--------------------------
+ (idx_expression,t,t,t,t)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE lower(data) = 'data 500';
+                      QUERY PLAN                      
+------------------------------------------------------
+ Bitmap Heap Scan on index_test
+   Recheck Cond: (lower(data) = 'data 500'::text)
+   ->  Bitmap Index Scan on idx_expression
+         Index Cond: (lower(data) = 'data 500'::text)
+(4 rows)
+
+ALTER INDEX idx_expression DISABLE;
+SELECT show_index_status('idx_expression');
+    show_index_status     
+--------------------------
+ (idx_expression,t,t,t,f)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE lower(data) = 'data 500';
+                 QUERY PLAN                 
+--------------------------------------------
+ Seq Scan on index_test
+   Filter: (lower(data) = 'data 500'::text)
+(2 rows)
+
+ALTER INDEX idx_expression ENABLE;
+SELECT show_index_status('idx_expression');
+    show_index_status     
+--------------------------
+ (idx_expression,t,t,t,t)
+(1 row)
+
+-- 5. GIN index
+CREATE INDEX idx_gin ON index_test USING gin(vector);
+SELECT show_index_status('idx_gin');
+ show_index_status 
+-------------------
+ (idx_gin,t,t,t,t)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE vector @> ARRAY[500];
+                     QUERY PLAN                     
+----------------------------------------------------
+ Bitmap Heap Scan on index_test
+   Recheck Cond: (vector @> '{500}'::integer[])
+   ->  Bitmap Index Scan on idx_gin
+         Index Cond: (vector @> '{500}'::integer[])
+(4 rows)
+
+ALTER INDEX idx_gin DISABLE;
+SELECT show_index_status('idx_gin');
+ show_index_status 
+-------------------
+ (idx_gin,t,t,t,f)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE vector @> ARRAY[500];
+                QUERY PLAN                
+------------------------------------------
+ Seq Scan on index_test
+   Filter: (vector @> '{500}'::integer[])
+(2 rows)
+
+ALTER INDEX idx_gin ENABLE;
+SELECT show_index_status('idx_gin');
+ show_index_status 
+-------------------
+ (idx_gin,t,t,t,t)
+(1 row)
+
+-- 6. GiST index
+CREATE INDEX idx_gist ON index_test USING gist(range);
+SELECT show_index_status('idx_gist');
+ show_index_status  
+--------------------
+ (idx_gist,t,t,t,t)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE range && int4range(100, 110);
+                      QUERY PLAN                       
+-------------------------------------------------------
+ Bitmap Heap Scan on index_test
+   Recheck Cond: (range && '[100,110)'::int4range)
+   ->  Bitmap Index Scan on idx_gist
+         Index Cond: (range && '[100,110)'::int4range)
+(4 rows)
+
+ALTER INDEX idx_gist DISABLE;
+SELECT show_index_status('idx_gist');
+ show_index_status  
+--------------------
+ (idx_gist,t,t,t,f)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE range && int4range(100, 110);
+                 QUERY PLAN                  
+---------------------------------------------
+ Seq Scan on index_test
+   Filter: (range && '[100,110)'::int4range)
+(2 rows)
+
+ALTER INDEX idx_gist ENABLE;
+SELECT show_index_status('idx_gist');
+ show_index_status  
+--------------------
+ (idx_gist,t,t,t,t)
+(1 row)
+
+-- 7. Covering index
+CREATE INDEX idx_covering ON index_test(num) INCLUDE (data);
+SELECT show_index_status('idx_covering');
+   show_index_status    
+------------------------
+ (idx_covering,t,t,t,t)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT num, data FROM index_test WHERE num = 50;
+               QUERY PLAN                
+-----------------------------------------
+ Bitmap Heap Scan on index_test
+   Recheck Cond: (num = 50)
+   ->  Bitmap Index Scan on idx_covering
+         Index Cond: (num = 50)
+(4 rows)
+
+ALTER INDEX idx_covering DISABLE;
+SELECT show_index_status('idx_covering');
+   show_index_status    
+------------------------
+ (idx_covering,t,t,t,f)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT num, data FROM index_test WHERE num = 50;
+              QUERY PLAN              
+--------------------------------------
+ Bitmap Heap Scan on index_test
+   Recheck Cond: (num = 50)
+   ->  Bitmap Index Scan on idx_multi
+         Index Cond: (num = 50)
+(4 rows)
+
+ALTER INDEX idx_covering ENABLE;
+SELECT show_index_status('idx_covering');
+   show_index_status    
+------------------------
+ (idx_covering,t,t,t,t)
+(1 row)
+
+-- 8. Unique index
+CREATE UNIQUE INDEX idx_unique ON index_test(id, data);
+SELECT show_index_status('idx_unique');
+  show_index_status   
+----------------------
+ (idx_unique,t,t,t,t)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE id = 500 AND data = 'data 500';
+                        QUERY PLAN                        
+----------------------------------------------------------
+ Index Scan using idx_unique on index_test
+   Index Cond: ((id = 500) AND (data = 'data 500'::text))
+(2 rows)
+
+ALTER INDEX idx_unique DISABLE;
+SELECT show_index_status('idx_unique');
+  show_index_status   
+----------------------
+ (idx_unique,t,t,t,f)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE id = 500 AND data = 'data 500';
+                   QUERY PLAN                   
+------------------------------------------------
+ Index Scan using index_test_pkey on index_test
+   Index Cond: (id = 500)
+   Filter: (data = 'data 500'::text)
+(3 rows)
+
+ALTER INDEX idx_unique ENABLE;
+SELECT show_index_status('idx_unique');
+  show_index_status   
+----------------------
+ (idx_unique,t,t,t,t)
+(1 row)
+
+-- 9. Function-based index
+CREATE INDEX idx_func ON index_test(get_data_length(data));
+SELECT show_index_status('idx_func');
+ show_index_status  
+--------------------
+ (idx_func,t,t,t,t)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE get_data_length(data) = 10;
+               QUERY PLAN                
+-----------------------------------------
+ Bitmap Heap Scan on index_test
+   Recheck Cond: (length(data) = 10)
+   ->  Bitmap Index Scan on idx_func
+         Index Cond: (length(data) = 10)
+(4 rows)
+
+ALTER INDEX idx_func DISABLE;
+SELECT show_index_status('idx_func');
+ show_index_status  
+--------------------
+ (idx_func,t,t,t,f)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE get_data_length(data) = 10;
+          QUERY PLAN           
+-------------------------------
+ Seq Scan on index_test
+   Filter: (length(data) = 10)
+(2 rows)
+
+ALTER INDEX idx_func ENABLE;
+SELECT show_index_status('idx_func');
+ show_index_status  
+--------------------
+ (idx_func,t,t,t,t)
+(1 row)
+
+-- 10. Join index
+CREATE TABLE join_test (id INT PRIMARY KEY, ref_id INT);
+INSERT INTO join_test SELECT g, g % 100 FROM generate_series(1, 1000) g;
+CREATE INDEX idx_join ON join_test(ref_id);
+SELECT show_index_status('idx_join');
+ show_index_status  
+--------------------
+ (idx_join,t,t,t,t)
+(1 row)
+
+EXPLAIN (COSTS OFF)
+SELECT jt.id, it.data
+FROM join_test jt
+JOIN index_test it ON jt.ref_id = it.num
+WHERE jt.id BETWEEN 100 AND 200;
+                          QUERY PLAN                           
+---------------------------------------------------------------
+ Hash Join
+   Hash Cond: (it.num = jt.ref_id)
+   ->  Seq Scan on index_test it
+   ->  Hash
+         ->  Bitmap Heap Scan on join_test jt
+               Recheck Cond: ((id >= 100) AND (id <= 200))
+               ->  Bitmap Index Scan on join_test_pkey
+                     Index Cond: ((id >= 100) AND (id <= 200))
+(8 rows)
+
+-- Disable all indexes to force seq scan
+ALTER INDEX idx_join DISABLE;
+ALTER INDEX join_test_pkey DISABLE;
+SELECT show_index_status('idx_join');
+ show_index_status  
+--------------------
+ (idx_join,t,t,t,f)
+(1 row)
+
+SELECT show_index_status('join_test_pkey');
+    show_index_status     
+--------------------------
+ (join_test_pkey,t,t,t,f)
+(1 row)
+
+EXPLAIN (COSTS OFF)
+SELECT jt.id, it.data
+FROM join_test jt
+JOIN index_test it ON jt.ref_id = it.num
+WHERE jt.id BETWEEN 100 AND 200;
+                     QUERY PLAN                      
+-----------------------------------------------------
+ Hash Join
+   Hash Cond: (it.num = jt.ref_id)
+   ->  Seq Scan on index_test it
+   ->  Hash
+         ->  Seq Scan on join_test jt
+               Filter: ((id >= 100) AND (id <= 200))
+(6 rows)
+
+ALTER INDEX idx_join ENABLE;
+ALTER INDEX join_test_pkey ENABLE;
+SELECT show_index_status('idx_join');
+ show_index_status  
+--------------------
+ (idx_join,t,t,t,t)
+(1 row)
+
+SELECT show_index_status('join_test_pkey');
+    show_index_status     
+--------------------------
+ (join_test_pkey,t,t,t,t)
+(1 row)
+
+-- Test REINDEX CONCURRENTLY
+REINDEX INDEX CONCURRENTLY idx_join;
+SELECT show_index_status('idx_join');
+ show_index_status  
+--------------------
+ (idx_join,t,t,t,t)
+(1 row)
+
+ALTER INDEX idx_join DISABLE;
+SELECT show_index_status('idx_join');
+ show_index_status  
+--------------------
+ (idx_join,t,t,t,f)
+(1 row)
+
+REINDEX INDEX CONCURRENTLY idx_join;
+SELECT show_index_status('idx_join');
+ show_index_status  
+--------------------
+ (idx_join,t,t,t,f)
+(1 row)
+
+SELECT pg_get_indexdef('idx_join'::regclass);
+                                  pg_get_indexdef                                  
+-----------------------------------------------------------------------------------
+ CREATE INDEX idx_join ON schema_to_reindex.join_test USING btree (ref_id) DISABLE
+(1 row)
+
+ALTER INDEX idx_join ENABLE;
+SELECT pg_get_indexdef('idx_join'::regclass);
+                              pg_get_indexdef                              
+---------------------------------------------------------------------------
+ CREATE INDEX idx_join ON schema_to_reindex.join_test USING btree (ref_id)
+(1 row)
+
+-- Test enable/disable index with indcheckxmin being true
+CREATE TABLE indcheckxmin_test(id int PRIMARY KEY);
+INSERT INTO indcheckxmin_test VALUES (1), (2), (3);
+CREATE INDEX CONCURRENTLY idx_checkxmin ON indcheckxmin_test(id);
+BEGIN;
+-- Simulate indcheckxmin being true
+UPDATE pg_index SET indcheckxmin = true WHERE indexrelid = 'idx_checkxmin'::regclass;
+ALTER INDEX idx_checkxmin DISABLE;  -- expect fail
+ERROR:  cannot enable/disable index while indcheckxmin is true
+HINT:  Wait for all transactions that might see inconsistent HOT chains to complete
+ROLLBACK;
+-- Test prepared statements with enabled/disabled indexes
+CREATE TABLE prep_idx_test (id int, data text);
+CREATE INDEX prep_idx1 ON prep_idx_test(data);
+INSERT INTO prep_idx_test SELECT g, 'data ' || g FROM generate_series(1,100) g;
+-- Test with enabled index
+PREPARE idx_plan AS SELECT * FROM prep_idx_test WHERE data = $1;
+EXPLAIN (COSTS OFF) EXECUTE idx_plan('data 1');
+                 QUERY PLAN                  
+---------------------------------------------
+ Bitmap Heap Scan on prep_idx_test
+   Recheck Cond: (data = 'data 1'::text)
+   ->  Bitmap Index Scan on prep_idx1
+         Index Cond: (data = 'data 1'::text)
+(4 rows)
+
+EXECUTE idx_plan('data 1');
+ id |  data  
+----+--------
+  1 | data 1
+(1 row)
+
+-- Test with disabled index
+ALTER INDEX prep_idx1 DISABLE;
+EXPLAIN (COSTS OFF) EXECUTE idx_plan('data 1');
+            QUERY PLAN             
+-----------------------------------
+ Seq Scan on prep_idx_test
+   Filter: (data = 'data 1'::text)
+(2 rows)
+
+EXECUTE idx_plan('data 1');
+ id |  data  
+----+--------
+  1 | data 1
+(1 row)
+
+-- Re-enable and test again
+ALTER INDEX prep_idx1 ENABLE;
+EXPLAIN (COSTS OFF) EXECUTE idx_plan('data 1');
+                 QUERY PLAN                  
+---------------------------------------------
+ Bitmap Heap Scan on prep_idx_test
+   Recheck Cond: (data = 'data 1'::text)
+   ->  Bitmap Index Scan on prep_idx1
+         Index Cond: (data = 'data 1'::text)
+(4 rows)
+
+EXECUTE idx_plan('data 1');
+ id |  data  
+----+--------
+  1 | data 1
+(1 row)
+
+-- Clean up
+DROP TABLE index_test;
+DROP TABLE join_test;
+DROP FUNCTION get_data_length;
+DROP FUNCTION show_index_status;
+DROP TABLE indcheckxmin_test CASCADE;
+DEALLOCATE idx_plan;
+DROP TABLE prep_idx_test;
 -- Failure for unauthorized user
 CREATE ROLE regress_reindexuser NOLOGIN;
 SET SESSION ROLE regress_reindexuser;
diff --git a/src/test/regress/sql/create_index.sql b/src/test/regress/sql/create_index.sql
index c085e05f05..dcb58d1ddd 100644
--- a/src/test/regress/sql/create_index.sql
+++ b/src/test/regress/sql/create_index.sql
@@ -1410,6 +1410,220 @@ END;
 -- concurrently
 REINDEX SCHEMA CONCURRENTLY schema_to_reindex;
 
+-- Test enable/disable functionality for indexes
+
+CREATE TABLE index_test(
+    id INT PRIMARY KEY,
+    data TEXT,
+    num INT,
+    vector INT[],
+    range INT4RANGE
+);
+
+INSERT INTO index_test
+SELECT
+    g,
+    'data ' || g,
+    g % 100,
+    ARRAY[g, g+1, g+2],
+    int4range(g, g+10)
+FROM generate_series(1, 1000) g;
+
+-- Function for testing
+CREATE FUNCTION get_data_length(text) RETURNS INT AS $$
+    SELECT length($1);
+$$ LANGUAGE SQL IMMUTABLE;
+
+-- Helper function to show index status
+CREATE OR REPLACE FUNCTION show_index_status(index_name text)
+RETURNS TABLE (
+    indexrelid regclass,
+    indisvalid boolean,
+    indisready boolean,
+    indislive boolean,
+    indisenabled boolean
+) AS $$
+BEGIN
+    RETURN QUERY EXECUTE format('
+        SELECT indexrelid::regclass, indisvalid, indisready, indislive, indisenabled
+        FROM pg_index
+        WHERE indexrelid = %L::regclass', index_name);
+END;
+$$ LANGUAGE plpgsql;
+
+-- Create and test each index type
+-- 1. Basic single-column index
+CREATE INDEX idx_single ON index_test(data);
+SELECT show_index_status('idx_single');
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE data = 'data 500';
+ALTER INDEX idx_single DISABLE;
+SELECT show_index_status('idx_single');
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE data = 'data 500';
+ALTER INDEX idx_single ENABLE;
+SELECT show_index_status('idx_single');
+
+-- 2. Multi-column index
+CREATE INDEX idx_multi ON index_test(num, data);
+SELECT show_index_status('idx_multi');
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE num = 50 AND data > 'data 500';
+ALTER INDEX idx_multi DISABLE;
+SELECT show_index_status('idx_multi');
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE num = 50 AND data > 'data 500';
+ALTER INDEX idx_multi ENABLE;
+SELECT show_index_status('idx_multi');
+
+-- 3. Partial index
+CREATE INDEX idx_partial ON index_test(num) WHERE num < 50;
+SELECT show_index_status('idx_partial');
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE num = 25;
+ALTER INDEX idx_partial DISABLE;
+SELECT show_index_status('idx_partial');
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE num = 25;
+ALTER INDEX idx_partial ENABLE;
+SELECT show_index_status('idx_partial');
+
+-- 4. Expression index
+CREATE INDEX idx_expression ON index_test((lower(data)));
+SELECT show_index_status('idx_expression');
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE lower(data) = 'data 500';
+ALTER INDEX idx_expression DISABLE;
+SELECT show_index_status('idx_expression');
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE lower(data) = 'data 500';
+ALTER INDEX idx_expression ENABLE;
+SELECT show_index_status('idx_expression');
+
+-- 5. GIN index
+CREATE INDEX idx_gin ON index_test USING gin(vector);
+SELECT show_index_status('idx_gin');
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE vector @> ARRAY[500];
+ALTER INDEX idx_gin DISABLE;
+SELECT show_index_status('idx_gin');
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE vector @> ARRAY[500];
+ALTER INDEX idx_gin ENABLE;
+SELECT show_index_status('idx_gin');
+
+-- 6. GiST index
+CREATE INDEX idx_gist ON index_test USING gist(range);
+SELECT show_index_status('idx_gist');
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE range && int4range(100, 110);
+ALTER INDEX idx_gist DISABLE;
+SELECT show_index_status('idx_gist');
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE range && int4range(100, 110);
+ALTER INDEX idx_gist ENABLE;
+SELECT show_index_status('idx_gist');
+
+-- 7. Covering index
+CREATE INDEX idx_covering ON index_test(num) INCLUDE (data);
+SELECT show_index_status('idx_covering');
+EXPLAIN (COSTS OFF) SELECT num, data FROM index_test WHERE num = 50;
+ALTER INDEX idx_covering DISABLE;
+SELECT show_index_status('idx_covering');
+EXPLAIN (COSTS OFF) SELECT num, data FROM index_test WHERE num = 50;
+ALTER INDEX idx_covering ENABLE;
+SELECT show_index_status('idx_covering');
+
+-- 8. Unique index
+CREATE UNIQUE INDEX idx_unique ON index_test(id, data);
+SELECT show_index_status('idx_unique');
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE id = 500 AND data = 'data 500';
+ALTER INDEX idx_unique DISABLE;
+SELECT show_index_status('idx_unique');
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE id = 500 AND data = 'data 500';
+ALTER INDEX idx_unique ENABLE;
+SELECT show_index_status('idx_unique');
+
+-- 9. Function-based index
+CREATE INDEX idx_func ON index_test(get_data_length(data));
+SELECT show_index_status('idx_func');
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE get_data_length(data) = 10;
+ALTER INDEX idx_func DISABLE;
+SELECT show_index_status('idx_func');
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE get_data_length(data) = 10;
+ALTER INDEX idx_func ENABLE;
+SELECT show_index_status('idx_func');
+
+-- 10. Join index
+CREATE TABLE join_test (id INT PRIMARY KEY, ref_id INT);
+INSERT INTO join_test SELECT g, g % 100 FROM generate_series(1, 1000) g;
+CREATE INDEX idx_join ON join_test(ref_id);
+SELECT show_index_status('idx_join');
+
+EXPLAIN (COSTS OFF)
+SELECT jt.id, it.data
+FROM join_test jt
+JOIN index_test it ON jt.ref_id = it.num
+WHERE jt.id BETWEEN 100 AND 200;
+
+-- Disable all indexes to force seq scan
+ALTER INDEX idx_join DISABLE;
+ALTER INDEX join_test_pkey DISABLE;
+SELECT show_index_status('idx_join');
+SELECT show_index_status('join_test_pkey');
+
+EXPLAIN (COSTS OFF)
+SELECT jt.id, it.data
+FROM join_test jt
+JOIN index_test it ON jt.ref_id = it.num
+WHERE jt.id BETWEEN 100 AND 200;
+
+ALTER INDEX idx_join ENABLE;
+ALTER INDEX join_test_pkey ENABLE;
+SELECT show_index_status('idx_join');
+SELECT show_index_status('join_test_pkey');
+
+-- Test REINDEX CONCURRENTLY
+REINDEX INDEX CONCURRENTLY idx_join;
+SELECT show_index_status('idx_join');
+
+ALTER INDEX idx_join DISABLE;
+SELECT show_index_status('idx_join');
+REINDEX INDEX CONCURRENTLY idx_join;
+SELECT show_index_status('idx_join');
+
+SELECT pg_get_indexdef('idx_join'::regclass);
+ALTER INDEX idx_join ENABLE;
+SELECT pg_get_indexdef('idx_join'::regclass);
+
+-- Test enable/disable index with indcheckxmin being true
+
+CREATE TABLE indcheckxmin_test(id int PRIMARY KEY);
+INSERT INTO indcheckxmin_test VALUES (1), (2), (3);
+CREATE INDEX CONCURRENTLY idx_checkxmin ON indcheckxmin_test(id);
+BEGIN;
+-- Simulate indcheckxmin being true
+UPDATE pg_index SET indcheckxmin = true WHERE indexrelid = 'idx_checkxmin'::regclass;
+ALTER INDEX idx_checkxmin DISABLE;  -- expect fail
+ROLLBACK;
+
+-- Test prepared statements with enabled/disabled indexes
+CREATE TABLE prep_idx_test (id int, data text);
+CREATE INDEX prep_idx1 ON prep_idx_test(data);
+INSERT INTO prep_idx_test SELECT g, 'data ' || g FROM generate_series(1,100) g;
+
+-- Test with enabled index
+PREPARE idx_plan AS SELECT * FROM prep_idx_test WHERE data = $1;
+EXPLAIN (COSTS OFF) EXECUTE idx_plan('data 1');
+EXECUTE idx_plan('data 1');
+
+-- Test with disabled index
+ALTER INDEX prep_idx1 DISABLE;
+EXPLAIN (COSTS OFF) EXECUTE idx_plan('data 1');
+EXECUTE idx_plan('data 1');
+
+-- Re-enable and test again
+ALTER INDEX prep_idx1 ENABLE;
+EXPLAIN (COSTS OFF) EXECUTE idx_plan('data 1');
+EXECUTE idx_plan('data 1');
+
+-- Clean up
+DROP TABLE index_test;
+DROP TABLE join_test;
+DROP FUNCTION get_data_length;
+DROP FUNCTION show_index_status;
+DROP TABLE indcheckxmin_test CASCADE;
+DEALLOCATE idx_plan;
+DROP TABLE prep_idx_test;
+
 -- Failure for unauthorized user
 CREATE ROLE regress_reindexuser NOLOGIN;
 SET SESSION ROLE regress_reindexuser;
-- 
2.39.5 (Apple Git-154)

#55Shayon Mukherjee
shayonj@gmail.com
In reply to: Michail Nikolaev (#52)
Re: Proposal to Enable/Disable Index using ALTER INDEX (with patch)

On Mon, Dec 30, 2024 at 3:48 PM Michail Nikolaev <michail.nikolaev@gmail.com>
wrote:

Hello!

One more thing (maybe I missed it in the patch, but anyway) - should we
add some migration to ensure what old databases will get enabled=true by
default after upgrade?

Hi!

Thank you! I tested this by manually upgrading (using pg_upgrade) from
master to the build from the branch, which ensures that post-upgrade the
column for indisenabled is true by default. I also backed it up with bool
indisenabled BKI_DEFAULT(t); in pg_index.h. Additionally, I tested
upgrading from an old data directory to the new one (both on this patch) to
ensure indexes with DISABLE properties are carried over as well on the new
data directory/upgrade. For reference the latest patch now is in [1]/messages/by-id/CANqtF-qOtDDktykqSFQO=UrDyRuF4fKPBQFaYuY1Eo4M0J8cpA@mail.gmail.com.

Given this is working as expected, would we still need a migration step?
(Let me know if I missed something ofc).

For reference here is the setup from my local testing (for reference)

rm -Rf /tmp/pg_data && rm -Rf /tmp/pg_data_new
./configure --prefix=/tmp/pg_install_old && make clean && make -j8 && make
install

# Create and init old cluster
/tmp/pg_install_old/bin/initdb -D /tmp/pg_data
/tmp/pg_install_old/bin/pg_ctl -D /tmp/pg_data start

# Create test data
/tmp/pg_install_old/bin/createdb test
/tmp/pg_install_old/bin/psql test -c "CREATE TABLE foo (id int); CREATE
INDEX idx_foo ON foo(id) DISABLE;"

# Stop old cluster
/tmp/pg_install_old/bin/pg_ctl -D /tmp/pg_data stop

# Switch branch and build new version
git checkout s/enable-disable-index
./configure --prefix=/tmp/pg_install_new && make clean && make -j8 && make
install

# Create new cluster directory
/tmp/pg_install_new/bin/initdb -D /tmp/pg_data_new

# Now run upgrade with different binary locations
/tmp/pg_install_new/bin/pg_upgrade \
-b /tmp/pg_install_old/bin \
-B /tmp/pg_install_new/bin \
-d /tmp/pg_data \
-D /tmp/pg_data_new \
-p 5432 \
-P 5433

/tmp/pg_install_new/bin/pg_ctl -D /tmp/pg_data_new start
$ SELECT * FROM pg_index WHERE indexrelid = 'idx_foo'::regclass;

Thank you
Shayon
[1]: /messages/by-id/CANqtF-qOtDDktykqSFQO=UrDyRuF4fKPBQFaYuY1Eo4M0J8cpA@mail.gmail.com
/messages/by-id/CANqtF-qOtDDktykqSFQO=UrDyRuF4fKPBQFaYuY1Eo4M0J8cpA@mail.gmail.com

#56Michail Nikolaev
michail.nikolaev@gmail.com
In reply to: Shayon Mukherjee (#55)
Re: Proposal to Enable/Disable Index using ALTER INDEX (with patch)

Hello!

Given this is working as expected, would we still need a migration step?

No, it is clear now. Thanks for explaining.

Best regards,
Mikhail.

#57Sami Imseih
samimseih@gmail.com
In reply to: Michail Nikolaev (#56)
Re: Proposal to Enable/Disable Index using ALTER INDEX (with patch)
+       This is the
+      default state for newly created indexes.

This is not needed in the ALTER INDEX docs, IMO.ss

+     <para>
+      Disable the specified index. A disabled index is not used for
queries, but it
+      is still updated when the underlying table data changes and will still be
+      used to enforce constraints (such as UNIQUE, or PRIMARY KEY constraints).
+      This can be useful for testing query performance with and
without specific
+      indexes. If performance degrades after disabling an index, it
can be easily
+      re-enabled using <literal>ENABLE</literal>. Before disabling,
it's recommended
+      to check
<structname>pg_stat_user_indexes</structname>.<structfield>idx_scan</structfield>
+      to identify potentially unused indexes.
+     </para>

This got me thinking if dropping the index is the only
use case we really care about. For example, you may want
to prevent an index that is enforcing a constraint from
being used by the planner, but you probably don't want to
drop it. In fact, I also think that you may want the index
from being used in one part of your application but could
potentially benefit other parts of your application. In that
case, I can see a GUC that allows you to force the use of a
an index that has been CREATED or ALTERED as DISABLED.
UNlike the GUC suggested earlier in the thread, this GUC
can simply be a boolean to allow the force usage of a
DISABLED index. FWIW, Oracle has a similar parameter called
OPTIMIZER_USE_INVISIBLE_INDEXES.

+        underlying table data changes. This can be useful when you
want to create
+        an index without immediately impacting query performance,
allowing you to

c/performance/planning ??

I have also been thinking about DISABLE as the keyword,
and I really don't like it. DISABLE indicates, at least ot me,
that the index is not available for either reads or writes.

Looking at other engines, Sqlserver uses DISABLE to drop
the index data, but keeps the index metadata around.

Oracle uses INVISIBLE and MariabDB uses IGNORABLE to
provide similar functionality to that being discussed here. I
find those keywords to be more appropriate for this purpose.

What about if we use HIDDEN instead of DISABLE as the keyword?

Regards,

Sami

#58Shayon Mukherjee
shayonj@gmail.com
In reply to: Sami Imseih (#57)
1 attachment(s)
Re: Proposal to Enable/Disable Index using ALTER INDEX (with patch)

On Fri, Jan 3, 2025 at 4:09 PM Sami Imseih <samimseih@gmail.com> wrote:

+       This is the
+      default state for newly created indexes.

This is not needed in the ALTER INDEX docs, IMO.ss

Updated and attached the patch.

This got me thinking if dropping the index is the only
use case we really care about. For example, you may want
to prevent an index that is enforcing a constraint from
being used by the planner, but you probably don't want to
drop it. In fact, I also think that you may want the index
from being used in one part of your application but could
potentially benefit other parts of your application. In that
case, I can see a GUC that allows you to force the use of a
an index that has been CREATED or ALTERED as DISABLED.
UNlike the GUC suggested earlier in the thread, this GUC
can simply be a boolean to allow the force usage of a
DISABLED index. FWIW, Oracle has a similar parameter called
OPTIMIZER_USE_INVISIBLE_INDEXES.

I totally see where you are coming from. Some rough thoughts/notes:

- The patch/proposed feature today doesn't disable constraints, like
uniqueness. It only impacts query planning. Maybe it should ?
- I was imagining this feature as being short-lived in production - that
is, you disable a potential index to collect data on query performance and
then make a decision on whether you need the index permanently. However,
yes, one can always keep an index disabled for longer, and conditionally
use it in another part of an application in which case a GUC to bypass the
disabled/invisible index would come in handy as you mentioned.
- I don't have a strong opinion either way, but I do wonder - considering
that this GUC is an additive feature - if it's something worth implementing
once we have more feedback from the usage (in v18 pre release, alpha, ec)
of marking an index as disabled/invisible first? Or perhaps as a follow-up
patch?

If we do go with a GUC - is FORCE_INVISIBLE_INDEX a good name?

+        underlying table data changes. This can be useful when you
want to create
+        an index without immediately impacting query performance,
allowing you to

c/performance/planning ??

Updated and attached the patch.

I have also been thinking about DISABLE as the keyword,
and I really don't like it. DISABLE indicates, at least ot me,
that the index is not available for either reads or writes.

Looking at other engines, Sqlserver uses DISABLE to drop
the index data, but keeps the index metadata around.

Oracle uses INVISIBLE and MariabDB uses IGNORABLE to
provide similar functionality to that being discussed here. I
find those keywords to be more appropriate for this purpose.

What about if we use HIDDEN instead of DISABLE as the keyword?

I agree. DISABLE doesn't sit right. I noticed INVISIBLE in MariaDB. I like
HIDDEN/VISIBLE or ACTIVE/INACTIVE as well, since it impacts query planning.

Happy to propose a patch with HIDDEN/VISIBLE if that sounds like a good
idea.

Thank you
Shayon

Attachments:

v8-0001-Introduce-the-ability-to-enable-disable-indexes-u.patchapplication/octet-stream; name=v8-0001-Introduce-the-ability-to-enable-disable-indexes-u.patchDownload
From 28dabf9ba309a63458c1c194cc0a1943d43ff498 Mon Sep 17 00:00:00 2001
From: Shayon Mukherjee <shayonj@gmail.com>
Date: Thu, 17 Oct 2024 10:04:13 -0400
Subject: [PATCH v8] Introduce the ability to enable/disable indexes using
 ALTER INDEX

This patch introduces the ability to enable or disable indexes using ALTER INDEX
and CREATE INDEX commands.

Original motivation for the problem and proposal for a patch
can be found at [1].

This patch passes all the existing specs and the newly added regression tests. The patch
is ready for review and test. It compiles, so the can patch can be applied for testing as well.

Implementation details:

- New Grammar:
  * ALTER INDEX ... ENABLE/DISABLE
  * CREATE INDEX ... DISABLE

- Default state is enabled. Indexes are only disabled when explicitly
  instructed via CREATE INDEX ... DISABLE or ALTER INDEX ... DISABLE.

- Primary Key and Unique constraint indexes are always enabled as well. The
  ENABLE/DISABLE grammar is not supported for these types of indexes. They can
  be later disabled via ALTER INDEX ... ENABLE/DISABLE.

- ALTER INDEX ... ENABLE/DISABLE performs update on the relevant row in pg_index
  catalog

- pg_get_indexdef() support the new functionality and grammar. This change is
  reflected in \d output for tables and pg_dump. We show the DISABLE syntax accordingly.

- Updated create_index.sql regression test to cover the new grammar and verify
  that disabled indexes are not used in queries. The test CATALOG_VERSION_NO

  - Basic single-column and multi-column indexes
  - Partial indexes
  - Expression indexes
  - Join indexes
  - GIN and GiST indexes
  - Covering indexes
  - Range indexes
  - Unique indexes and constraints

- Adds a new enabled attribute to the IndexOptInfo structure.

- Modifies get_relation_info in plancat.c to skip disabled indexes entirely, thus reducing the number of places we need to check if an index is disabled or not. Inspired by the conversations start at [2].
  - I chose to modify the logic within get_relation_info as compared to, say, reducing the cost to make the planner not consider an index during planning, mostly to keep the number of changes being introduced to a minimum and also the logic itself being self-contained and easier to under perhaps (?).

- No changes are made to stop the index from getting rebuilt. This way we ensure no
  data miss or corruption when index is re-nabled.

- TOAST indexes are supported and enabled by default as well.

- REINDEX CONCURRENTLY is supported as well and existing state of pg_index.indisenabled
  is carried over accordingly.

- See the changes in create_index.sql to get an idea of the grammar and sql statements.

- See the changes in create_index.out to get an idea of the catalogue states and EXPLAIN
  output to see when an index is getting used or isn't (when disabled).

- Incorporated DavidR's feedback from [3] around documentation and also you will see that by skip disabled indexes entirely from get_relation_info in plancat.c (as mentioned above), we address the other mentioned issues as well.

- Lastly, protects against the case where indcheckxmin is true by raising ERRCODE_OBJECT_NOT_IN_PREREQUISITE_STATE.

Looking forward to any and all feedback on this patch, including but not limited to code quality, tests, fundamental logic.

[1] https://www.postgresql.org/message-id/CANqtF-oXKe0M%3D0QOih6H%2BsZRjE2BWAbkW_1%2B9nMEAMLxUJg5jA%40mail.gmail.com
[2] https://www.postgresql.org/message-id/3465209.1727202064%40sss.pgh.pa.us
[3] https://www.postgresql.org/message-id/CAApHDvpUNu%3DiVcdJ74sypvgeaCF%2Btfpyb8VRhZaF7DTd1xVr7g%40mail.gmail.com
---
 doc/src/sgml/catalogs.sgml                 |  11 +
 doc/src/sgml/ref/alter_index.sgml          |  41 ++
 doc/src/sgml/ref/create_index.sgml         |  29 ++
 src/backend/bootstrap/bootparse.y          |   2 +
 src/backend/catalog/index.c                |  31 +-
 src/backend/catalog/toasting.c             |   2 +-
 src/backend/commands/indexcmds.c           |   4 +
 src/backend/commands/tablecmds.c           |  72 ++-
 src/backend/optimizer/util/plancat.c       |  11 +-
 src/backend/parser/gram.y                  |  48 +-
 src/backend/parser/parse_utilcmd.c         |   3 +
 src/backend/utils/adt/ruleutils.c          |   4 +
 src/backend/utils/cache/relcache.c         |   1 +
 src/include/catalog/index.h                |   2 +-
 src/include/catalog/pg_index.h             |   1 +
 src/include/nodes/parsenodes.h             |   3 +
 src/include/nodes/pathnodes.h              |   2 +
 src/test/regress/expected/create_index.out | 560 +++++++++++++++++++++
 src/test/regress/sql/create_index.sql      | 214 ++++++++
 19 files changed, 1025 insertions(+), 16 deletions(-)

diff --git a/doc/src/sgml/catalogs.sgml b/doc/src/sgml/catalogs.sgml
index 238ed67919..57ea5d2e8b 100644
--- a/doc/src/sgml/catalogs.sgml
+++ b/doc/src/sgml/catalogs.sgml
@@ -4595,6 +4595,17 @@ SCRAM-SHA-256$<replaceable>&lt;iteration count&gt;</replaceable>:<replaceable>&l
        partial index.
       </para></entry>
      </row>
+
+     <row>
+      <entry role="catalog_table_entry"><para role="column_definition">
+       <structfield>indisenabled</structfield> <type>bool</type>
+      </para>
+      <para>
+       If true, the index is currently enabled and may be used for queries.
+       If false, the index is disabled and may not be used for queries,
+       but is still updated when the table is modified. Default is true.
+      </para></entry>
+     </row>
     </tbody>
    </tgroup>
   </table>
diff --git a/doc/src/sgml/ref/alter_index.sgml b/doc/src/sgml/ref/alter_index.sgml
index 1d42d05d85..7b2ab1d74c 100644
--- a/doc/src/sgml/ref/alter_index.sgml
+++ b/doc/src/sgml/ref/alter_index.sgml
@@ -31,6 +31,8 @@ ALTER INDEX [ IF EXISTS ] <replaceable class="parameter">name</replaceable> ALTE
     SET STATISTICS <replaceable class="parameter">integer</replaceable>
 ALTER INDEX ALL IN TABLESPACE <replaceable class="parameter">name</replaceable> [ OWNED BY <replaceable class="parameter">role_name</replaceable> [, ... ] ]
     SET TABLESPACE <replaceable class="parameter">new_tablespace</replaceable> [ NOWAIT ]
+ALTER INDEX [ IF EXISTS ] <replaceable class="parameter">name</replaceable> ENABLE
+ALTER INDEX [ IF EXISTS ] <replaceable class="parameter">name</replaceable> DISABLE
 </synopsis>
  </refsynopsisdiv>
 
@@ -159,6 +161,31 @@ ALTER INDEX ALL IN TABLESPACE <replaceable class="parameter">name</replaceable>
     </listitem>
    </varlistentry>
 
+   <varlistentry>
+    <term><literal>ENABLE</literal></term>
+    <listitem>
+     <para>
+      Enable the specified index. The index will be used for queries.
+     </para>
+    </listitem>
+   </varlistentry>
+
+   <varlistentry>
+    <term><literal>DISABLE</literal></term>
+    <listitem>
+     <para>
+      Disable the specified index. A disabled index is not used for queries, but it
+      is still updated when the underlying table data changes and will still be
+      used to enforce constraints (such as UNIQUE, or PRIMARY KEY constraints).
+      This can be useful for testing query performance with and without specific
+      indexes. If performance degrades after disabling an index, it can be easily
+      re-enabled using <literal>ENABLE</literal>. Before disabling, it's recommended
+      to check <structname>pg_stat_user_indexes</structname>.<structfield>idx_scan</structfield>
+      to identify potentially unused indexes.
+     </para>
+    </listitem>
+   </varlistentry>
+
   </variablelist>
   </para>
 
@@ -301,6 +328,20 @@ CREATE INDEX coord_idx ON measured (x, y, (z + t));
 ALTER INDEX coord_idx ALTER COLUMN 3 SET STATISTICS 1000;
 </programlisting></para>
 
+  <para>
+   To enable an index:
+<programlisting>
+ALTER INDEX idx_name ENABLE;
+</programlisting>
+  </para>
+
+  <para>
+   To disable an index:
+<programlisting>
+ALTER INDEX idx_name DISABLE;
+</programlisting>
+  </para>
+
  </refsect1>
 
  <refsect1>
diff --git a/doc/src/sgml/ref/create_index.sgml b/doc/src/sgml/ref/create_index.sgml
index 208389e800..6476fa69c6 100644
--- a/doc/src/sgml/ref/create_index.sgml
+++ b/doc/src/sgml/ref/create_index.sgml
@@ -28,6 +28,7 @@ CREATE [ UNIQUE ] INDEX [ CONCURRENTLY ] [ [ IF NOT EXISTS ] <replaceable class=
     [ WITH ( <replaceable class="parameter">storage_parameter</replaceable> [= <replaceable class="parameter">value</replaceable>] [, ... ] ) ]
     [ TABLESPACE <replaceable class="parameter">tablespace_name</replaceable> ]
     [ WHERE <replaceable class="parameter">predicate</replaceable> ]
+    [ DISABLE ]
 </synopsis>
  </refsynopsisdiv>
 
@@ -380,6 +381,19 @@ CREATE [ UNIQUE ] INDEX [ CONCURRENTLY ] [ [ IF NOT EXISTS ] <replaceable class=
       </listitem>
      </varlistentry>
 
+    <varlistentry>
+      <term><literal>DISABLE</literal></term>
+      <listitem>
+       <para>
+        Creates the index in a disabled state (default enabled). A disabled index is not used by the
+        query planner for query optimization, but it is still maintained when the
+        underlying table data changes. This can be useful when you want to create
+        an index without immediately impacting query planning, allowing you to
+        enable it later at a more convenient time. The index can be enabled later
+        using <command>ALTER INDEX ... ENABLE</command>.
+       </para>
+      </listitem>
+     </varlistentry>
     </variablelist>
 
   <refsect2 id="sql-createindex-storage-parameters" xreflabel="Index Storage Parameters">
@@ -701,6 +715,14 @@ Indexes:
     partitioned index is a metadata only operation.
    </para>
 
+  <para>
+   When creating an index with the <literal>DISABLE</literal> option, the index
+   will be created but not used for query planning. This can be useful for
+   preparing an index in advance of its use, or for testing purposes. The index
+   will still be maintained as the table is modified, so it can be enabled
+   later without needing to be rebuilt. By default all new indexes are enabled.
+  </para>
+
   </refsect2>
  </refsect1>
 
@@ -980,6 +1002,13 @@ SELECT * FROM points
 CREATE INDEX CONCURRENTLY sales_quantity_index ON sales_table (quantity);
 </programlisting></para>
 
+  <para>
+   To create an index on the table <literal>test_table</literal> with the default
+   name, but have it initially disabled:
+<programlisting>
+CREATE INDEX ON test_table (col1) DISABLE;
+</programlisting>
+  </para>
  </refsect1>
 
  <refsect1>
diff --git a/src/backend/bootstrap/bootparse.y b/src/backend/bootstrap/bootparse.y
index 9833f52c1b..9eea080ab5 100644
--- a/src/backend/bootstrap/bootparse.y
+++ b/src/backend/bootstrap/bootparse.y
@@ -303,6 +303,7 @@ Boot_DeclareIndexStmt:
 					stmt->concurrent = false;
 					stmt->if_not_exists = false;
 					stmt->reset_default_tblspc = false;
+					stmt->isenabled = true;
 
 					/* locks and races need not concern us in bootstrap mode */
 					relationId = RangeVarGetRelid(stmt->relation, NoLock,
@@ -356,6 +357,7 @@ Boot_DeclareUniqueIndexStmt:
 					stmt->concurrent = false;
 					stmt->if_not_exists = false;
 					stmt->reset_default_tblspc = false;
+					stmt->isenabled = true;
 
 					/* locks and races need not concern us in bootstrap mode */
 					relationId = RangeVarGetRelid(stmt->relation, NoLock,
diff --git a/src/backend/catalog/index.c b/src/backend/catalog/index.c
index 7377912b41..0e9a1962c2 100644
--- a/src/backend/catalog/index.c
+++ b/src/backend/catalog/index.c
@@ -118,7 +118,8 @@ static void UpdateIndexRelation(Oid indexoid, Oid heapoid,
 								bool isexclusion,
 								bool immediate,
 								bool isvalid,
-								bool isready);
+								bool isready,
+								bool isenabled);
 static void index_update_stats(Relation rel,
 							   bool hasindex,
 							   double reltuples);
@@ -570,7 +571,8 @@ UpdateIndexRelation(Oid indexoid,
 					bool isexclusion,
 					bool immediate,
 					bool isvalid,
-					bool isready)
+					bool isready,
+					bool isenabled)
 {
 	int2vector *indkey;
 	oidvector  *indcollation;
@@ -648,6 +650,7 @@ UpdateIndexRelation(Oid indexoid,
 	values[Anum_pg_index_indisready - 1] = BoolGetDatum(isready);
 	values[Anum_pg_index_indislive - 1] = BoolGetDatum(true);
 	values[Anum_pg_index_indisreplident - 1] = BoolGetDatum(false);
+	values[Anum_pg_index_indisenabled - 1] = BoolGetDatum(isenabled);
 	values[Anum_pg_index_indkey - 1] = PointerGetDatum(indkey);
 	values[Anum_pg_index_indcollation - 1] = PointerGetDatum(indcollation);
 	values[Anum_pg_index_indclass - 1] = PointerGetDatum(indclass);
@@ -713,6 +716,8 @@ UpdateIndexRelation(Oid indexoid,
  *			already exists.
  *		INDEX_CREATE_PARTITIONED:
  *			create a partitioned index (table must be partitioned)
+ *		INDEX_CREATE_DISABLED:
+*				create the index as disabled if instructed, defaults to being enabled.
  * constr_flags: flags passed to index_constraint_create
  *		(only if INDEX_CREATE_ADD_CONSTRAINT is set)
  * allow_system_table_mods: allow table to be a system catalog
@@ -758,6 +763,7 @@ index_create(Relation heapRelation,
 	bool		invalid = (flags & INDEX_CREATE_INVALID) != 0;
 	bool		concurrent = (flags & INDEX_CREATE_CONCURRENT) != 0;
 	bool		partitioned = (flags & INDEX_CREATE_PARTITIONED) != 0;
+	bool 		isenabled  = (flags & INDEX_CREATE_ENABLED) != 0;
 	char		relkind;
 	TransactionId relfrozenxid;
 	MultiXactId relminmxid;
@@ -1041,13 +1047,15 @@ index_create(Relation heapRelation,
 	 *	  (Or, could define a rule to maintain the predicate) --Nels, Feb '92
 	 * ----------------
 	 */
+
 	UpdateIndexRelation(indexRelationId, heapRelationId, parentIndexRelid,
 						indexInfo,
 						collationIds, opclassIds, coloptions,
 						isprimary, is_exclusion,
 						(constr_flags & INDEX_CONSTR_CREATE_DEFERRABLE) == 0,
 						!concurrent && !invalid,
-						!concurrent);
+						!concurrent,
+						isenabled);
 
 	/*
 	 * Register relcache invalidation on the indexes' heap relation, to
@@ -1316,6 +1324,8 @@ index_concurrently_create_copy(Relation heapRelation, Oid oldIndexId,
 	List	   *indexColNames = NIL;
 	List	   *indexExprs = NIL;
 	List	   *indexPreds = NIL;
+	Form_pg_index indexForm;
+	bits16 	 createFlags;
 
 	indexRelation = index_open(oldIndexId, RowExclusiveLock);
 
@@ -1343,6 +1353,9 @@ index_concurrently_create_copy(Relation heapRelation, Oid oldIndexId,
 											Anum_pg_index_indoption);
 	indcoloptions = (int2vector *) DatumGetPointer(colOptionDatum);
 
+	/* Get the enabled state of the original index */
+	indexForm = (Form_pg_index) GETSTRUCT(indexTuple);
+
 	/* Fetch reloptions of index if any */
 	classTuple = SearchSysCache1(RELOID, ObjectIdGetDatum(oldIndexId));
 	if (!HeapTupleIsValid(classTuple))
@@ -1434,6 +1447,16 @@ index_concurrently_create_copy(Relation heapRelation, Oid oldIndexId,
 		stattargets[i].isnull = isnull;
 	}
 
+	/*
+	* Determine the create flags for the new index.
+	* We always use SKIP_BUILD and CONCURRENT for concurrent reindexing.
+	* If the original index was enabled, we also set the ENABLED flag
+	* to maintain the same state in the new index.
+	*/
+	createFlags = INDEX_CREATE_SKIP_BUILD | INDEX_CREATE_CONCURRENT;
+	if (indexForm->indisenabled)
+			createFlags |= INDEX_CREATE_ENABLED;
+
 	/*
 	 * Now create the new index.
 	 *
@@ -1457,7 +1480,7 @@ index_concurrently_create_copy(Relation heapRelation, Oid oldIndexId,
 							  indcoloptions->values,
 							  stattargets,
 							  reloptionsDatum,
-							  INDEX_CREATE_SKIP_BUILD | INDEX_CREATE_CONCURRENT,
+							  createFlags,
 							  0,
 							  true, /* allow table to be a system catalog? */
 							  false,	/* is_internal? */
diff --git a/src/backend/catalog/toasting.c b/src/backend/catalog/toasting.c
index 874a8fc89a..a612a0a3de 100644
--- a/src/backend/catalog/toasting.c
+++ b/src/backend/catalog/toasting.c
@@ -325,7 +325,7 @@ create_toast_table(Relation rel, Oid toastOid, Oid toastIndexOid,
 				 BTREE_AM_OID,
 				 rel->rd_rel->reltablespace,
 				 collationIds, opclassIds, NULL, coloptions, NULL, (Datum) 0,
-				 INDEX_CREATE_IS_PRIMARY, 0, true, true, NULL);
+				 INDEX_CREATE_IS_PRIMARY | INDEX_CREATE_ENABLED, 0, true, true, NULL);
 
 	table_close(toast_rel, NoLock);
 
diff --git a/src/backend/commands/indexcmds.c b/src/backend/commands/indexcmds.c
index d6e23caef1..8fceb060bb 100644
--- a/src/backend/commands/indexcmds.c
+++ b/src/backend/commands/indexcmds.c
@@ -1198,6 +1198,10 @@ DefineIndex(Oid tableId,
 		flags |= INDEX_CREATE_PARTITIONED;
 	if (stmt->primary)
 		flags |= INDEX_CREATE_IS_PRIMARY;
+   if (stmt->isenabled)
+		flags |= INDEX_CREATE_ENABLED;
+   else
+		flags &= ~INDEX_CREATE_ENABLED;
 
 	/*
 	 * If the table is partitioned, and recursion was declined but partitions
diff --git a/src/backend/commands/tablecmds.c b/src/backend/commands/tablecmds.c
index 4fc54bd6eb..90044afeea 100644
--- a/src/backend/commands/tablecmds.c
+++ b/src/backend/commands/tablecmds.c
@@ -688,7 +688,7 @@ static List *GetParentedForeignKeyRefs(Relation partition);
 static void ATDetachCheckNoForeignKeyRefs(Relation partition);
 static char GetAttributeCompression(Oid atttypid, const char *compression);
 static char GetAttributeStorage(Oid atttypid, const char *storagemode);
-
+static void ATExecEnableDisableIndex(Relation rel, bool enable);
 
 /* ----------------------------------------------------------------
  *		DefineRelation
@@ -4648,6 +4648,8 @@ AlterTableGetLockLevel(List *cmds)
 			case AT_SetExpression:
 			case AT_DropExpression:
 			case AT_SetCompression:
+			case AT_EnableIndex:
+			case AT_DisableIndex:
 				cmd_lockmode = AccessExclusiveLock;
 				break;
 
@@ -5210,6 +5212,12 @@ ATPrepCmd(List **wqueue, Relation rel, AlterTableCmd *cmd,
 			/* No command-specific prep needed */
 			pass = AT_PASS_MISC;
 			break;
+		case AT_EnableIndex:
+		case AT_DisableIndex:
+			ATSimplePermissions(cmd->subtype, rel, ATT_INDEX | ATT_PARTITIONED_INDEX);
+			/* No command-specific prep needed */
+			pass = AT_PASS_MISC;
+			break;
 		default:				/* oops */
 			elog(ERROR, "unrecognized alter table type: %d",
 				 (int) cmd->subtype);
@@ -5604,6 +5612,12 @@ ATExecCmd(List **wqueue, AlteredTableInfo *tab,
 		case AT_DetachPartitionFinalize:
 			address = ATExecDetachPartitionFinalize(rel, ((PartitionCmd *) cmd->def)->name);
 			break;
+		case AT_EnableIndex:
+				ATExecEnableDisableIndex(rel, true);
+				break;
+		case AT_DisableIndex:
+				ATExecEnableDisableIndex(rel, false);
+				break;
 		default:				/* oops */
 			elog(ERROR, "unrecognized alter table type: %d",
 				 (int) cmd->subtype);
@@ -6498,6 +6512,8 @@ alter_table_type_to_string(AlterTableType cmdtype)
 			return "DROP COLUMN";
 		case AT_AddIndex:
 		case AT_ReAddIndex:
+		case AT_EnableIndex:
+		case AT_DisableIndex:
 			return NULL;		/* not real grammar */
 		case AT_AddConstraint:
 		case AT_ReAddConstraint:
@@ -20861,3 +20877,57 @@ GetAttributeStorage(Oid atttypid, const char *storagemode)
 
 	return cstorage;
 }
+
+/*
+ * ATExecEnableDisableIndex
+ * Performs a catalog update to enable or disable an index in pg_index.
+ */
+static void
+ATExecEnableDisableIndex(Relation rel, bool enable)
+{
+	Oid         indexOid = RelationGetRelid(rel);
+	Oid         heapOid;
+	Relation    pg_index;
+	HeapTuple   indexTuple;
+	Form_pg_index indexForm;
+	bool        updated = false;
+	Relation    heapRel;
+
+	pg_index = table_open(IndexRelationId, RowExclusiveLock);
+
+	indexTuple = SearchSysCacheCopy1(INDEXRELID, ObjectIdGetDatum(indexOid));
+	if (!HeapTupleIsValid(indexTuple))
+		elog(ERROR, "could not find tuple for index %u", indexOid);
+
+	indexForm = (Form_pg_index) GETSTRUCT(indexTuple);
+	if (indexForm->indcheckxmin)
+	{
+		heap_freetuple(indexTuple);
+		table_close(pg_index, RowExclusiveLock);
+		ereport(ERROR,
+				(errcode(ERRCODE_OBJECT_NOT_IN_PREREQUISITE_STATE),
+				errmsg("cannot enable/disable index while indcheckxmin is true"),
+				errhint("Wait for all transactions that might see inconsistent HOT chains to complete")));
+	}
+
+	if (indexForm->indisenabled != enable)
+	{
+		indexForm->indisenabled = enable;
+
+		CatalogTupleUpdate(pg_index, &indexTuple->t_self, indexTuple);
+		updated = true;
+	}
+
+	heap_freetuple(indexTuple);
+	table_close(pg_index, RowExclusiveLock);
+
+	if (updated)
+	{
+		heapOid = IndexGetRelation(indexOid, false);
+		heapRel = table_open(heapOid, AccessShareLock);
+		CacheInvalidateRelcache(heapRel);
+		table_close(heapRel, AccessShareLock);
+		InvokeObjectPostAlterHook(IndexRelationId, indexOid, 0);
+		CommandCounterIncrement();
+	}
+}
diff --git a/src/backend/optimizer/util/plancat.c b/src/backend/optimizer/util/plancat.c
index f2d319101d..333657446b 100644
--- a/src/backend/optimizer/util/plancat.c
+++ b/src/backend/optimizer/util/plancat.c
@@ -254,13 +254,12 @@ get_relation_info(PlannerInfo *root, Oid relationObjectId, bool inhparent,
 			index = indexRelation->rd_index;
 
 			/*
-			 * Ignore invalid indexes, since they can't safely be used for
-			 * queries.  Note that this is OK because the data structure we
-			 * are constructing is only used by the planner --- the executor
-			 * still needs to insert into "invalid" indexes, if they're marked
-			 * indisready.
+			 * Ignore invalid or disabled indexes, since they can't safely be used for
+			 * queries. This is OK because the data structure we are constructing is
+			 * only used by the planner - the executor still needs to insert into
+			 * "invalid" indexes if they're marked indisready.
 			 */
-			if (!index->indisvalid)
+			if (!index->indisvalid || !index->indisenabled)
 			{
 				index_close(indexRelation, NoLock);
 				continue;
diff --git a/src/backend/parser/gram.y b/src/backend/parser/gram.y
index 6079de70e0..17fce6b956 100644
--- a/src/backend/parser/gram.y
+++ b/src/backend/parser/gram.y
@@ -322,7 +322,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 %type <ival>	add_drop opt_asc_desc opt_nulls_order
 
 %type <node>	alter_table_cmd alter_type_cmd opt_collate_clause
-	   replica_identity partition_cmd index_partition_cmd
+	   replica_identity partition_cmd index_partition_cmd index_alter_cmd
 %type <list>	alter_table_cmds alter_type_cmds
 %type <list>    alter_identity_column_option_list
 %type <defelt>  alter_identity_column_option
@@ -485,6 +485,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 %type <boolean> opt_unique opt_verbose opt_full
 %type <boolean> opt_freeze opt_analyze opt_default
 %type <defelt>	opt_binary copy_delimiter
+%type <boolean>  opt_index_enabled
 
 %type <boolean> copy_from opt_program
 
@@ -2151,6 +2152,24 @@ AlterTableStmt:
 					n->nowait = $13;
 					$$ = (Node *) n;
 				}
+		| ALTER INDEX qualified_name index_alter_cmd
+				{
+					AlterTableStmt *n = makeNode(AlterTableStmt);
+					n->relation = $3;
+					n->cmds = list_make1($4);
+					n->objtype = OBJECT_INDEX;
+					n->missing_ok = false;
+					$$ = (Node *) n;
+				}
+		| ALTER INDEX IF_P EXISTS qualified_name index_alter_cmd
+				{
+					AlterTableStmt *n = makeNode(AlterTableStmt);
+					n->relation = $5;
+					n->cmds = list_make1($6);
+					n->objtype = OBJECT_INDEX;
+					n->missing_ok = true;
+					$$ = (Node *) n;
+				}
 		|	ALTER INDEX qualified_name alter_table_cmds
 				{
 					AlterTableStmt *n = makeNode(AlterTableStmt);
@@ -2376,6 +2395,21 @@ index_partition_cmd:
 				}
 		;
 
+index_alter_cmd:
+		/* ALTER INDEX <name> ENABLE|DISABLE */
+		ENABLE_P
+			{
+				AlterTableCmd *n = makeNode(AlterTableCmd);
+				n->subtype = AT_EnableIndex;
+				$$ = (Node *) n;
+			}
+		| DISABLE_P
+			{
+				AlterTableCmd *n = makeNode(AlterTableCmd);
+				n->subtype = AT_DisableIndex;
+				$$ = (Node *) n;
+			}
+		;
 alter_table_cmd:
 			/* ALTER TABLE <name> ADD <coldef> */
 			ADD_P columnDef
@@ -8154,7 +8188,7 @@ defacl_privilege_target:
 
 IndexStmt:	CREATE opt_unique INDEX opt_concurrently opt_single_name
 			ON relation_expr access_method_clause '(' index_params ')'
-			opt_include opt_unique_null_treatment opt_reloptions OptTableSpace where_clause
+			opt_include opt_unique_null_treatment opt_reloptions OptTableSpace where_clause opt_index_enabled
 				{
 					IndexStmt *n = makeNode(IndexStmt);
 
@@ -8169,6 +8203,7 @@ IndexStmt:	CREATE opt_unique INDEX opt_concurrently opt_single_name
 					n->options = $14;
 					n->tableSpace = $15;
 					n->whereClause = $16;
+					n->isenabled = $17;
 					n->excludeOpNames = NIL;
 					n->idxcomment = NULL;
 					n->indexOid = InvalidOid;
@@ -8186,7 +8221,7 @@ IndexStmt:	CREATE opt_unique INDEX opt_concurrently opt_single_name
 				}
 			| CREATE opt_unique INDEX opt_concurrently IF_P NOT EXISTS name
 			ON relation_expr access_method_clause '(' index_params ')'
-			opt_include opt_unique_null_treatment opt_reloptions OptTableSpace where_clause
+			opt_include opt_unique_null_treatment opt_reloptions OptTableSpace where_clause opt_index_enabled
 				{
 					IndexStmt *n = makeNode(IndexStmt);
 
@@ -8201,6 +8236,7 @@ IndexStmt:	CREATE opt_unique INDEX opt_concurrently opt_single_name
 					n->options = $17;
 					n->tableSpace = $18;
 					n->whereClause = $19;
+					n->isenabled = $20;
 					n->excludeOpNames = NIL;
 					n->idxcomment = NULL;
 					n->indexOid = InvalidOid;
@@ -8223,6 +8259,12 @@ opt_unique:
 			| /*EMPTY*/								{ $$ = false; }
 		;
 
+opt_index_enabled:
+			ENABLE_P                      { $$ = true; }
+			| DISABLE_P                   { $$ = false; }
+			| /*EMPTY*/                 	{ $$ = true; }
+		;
+
 access_method_clause:
 			USING name								{ $$ = $2; }
 			| /*EMPTY*/								{ $$ = DEFAULT_INDEX_TYPE; }
diff --git a/src/backend/parser/parse_utilcmd.c b/src/backend/parser/parse_utilcmd.c
index ca028d2a66..f3d0d61204 100644
--- a/src/backend/parser/parse_utilcmd.c
+++ b/src/backend/parser/parse_utilcmd.c
@@ -1743,6 +1743,7 @@ generateClonedIndexStmt(RangeVar *heapRel, Relation source_idx,
 	index->concurrent = false;
 	index->if_not_exists = false;
 	index->reset_default_tblspc = false;
+	index->isenabled = idxrec->indisenabled;
 
 	/*
 	 * We don't try to preserve the name of the source index; instead, just
@@ -2364,6 +2365,8 @@ transformIndexConstraint(Constraint *constraint, CreateStmtContext *cxt)
 	index->concurrent = false;
 	index->if_not_exists = false;
 	index->reset_default_tblspc = constraint->reset_default_tblspc;
+	/* Ensure indexes for constraints are created as enabled by default */
+	index->isenabled = true;
 
 	/*
 	 * If it's ALTER TABLE ADD CONSTRAINT USING INDEX, look up the index and
diff --git a/src/backend/utils/adt/ruleutils.c b/src/backend/utils/adt/ruleutils.c
index 16d15f9efb..87a8ba746a 100644
--- a/src/backend/utils/adt/ruleutils.c
+++ b/src/backend/utils/adt/ruleutils.c
@@ -1559,6 +1559,10 @@ pg_get_indexdef_worker(Oid indexrelid, int colno,
 			else
 				appendStringInfo(&buf, " WHERE %s", str);
 		}
+
+		/* Add DISABLE clause if the index is disabled */
+		if (!idxrec->indisenabled)
+				appendStringInfoString(&buf, " DISABLE");
 	}
 
 	/* Clean up */
diff --git a/src/backend/utils/cache/relcache.c b/src/backend/utils/cache/relcache.c
index 43219a9629..ce08461e57 100644
--- a/src/backend/utils/cache/relcache.c
+++ b/src/backend/utils/cache/relcache.c
@@ -2311,6 +2311,7 @@ RelationReloadIndexInfo(Relation relation)
 		relation->rd_index->indisready = index->indisready;
 		relation->rd_index->indislive = index->indislive;
 		relation->rd_index->indisreplident = index->indisreplident;
+		relation->rd_index->indisenabled = index->indisenabled;
 
 		/* Copy xmin too, as that is needed to make sense of indcheckxmin */
 		HeapTupleHeaderSetXmin(relation->rd_indextuple->t_data,
diff --git a/src/include/catalog/index.h b/src/include/catalog/index.h
index 4daa8bef5e..50cd53c64e 100644
--- a/src/include/catalog/index.h
+++ b/src/include/catalog/index.h
@@ -65,6 +65,7 @@ extern void index_check_primary_key(Relation heapRel,
 #define	INDEX_CREATE_IF_NOT_EXISTS			(1 << 4)
 #define	INDEX_CREATE_PARTITIONED			(1 << 5)
 #define INDEX_CREATE_INVALID				(1 << 6)
+#define INDEX_CREATE_ENABLED        (1 << 7)
 
 extern Oid	index_create(Relation heapRelation,
 						 const char *indexRelationName,
@@ -175,7 +176,6 @@ extern void RestoreReindexState(const void *reindexstate);
 
 extern void IndexSetParentIndex(Relation partitionIdx, Oid parentOid);
 
-
 /*
  * itemptr_encode - Encode ItemPointer as int64/int8
  *
diff --git a/src/include/catalog/pg_index.h b/src/include/catalog/pg_index.h
index 9eb99d31fa..f74e394002 100644
--- a/src/include/catalog/pg_index.h
+++ b/src/include/catalog/pg_index.h
@@ -44,6 +44,7 @@ CATALOG(pg_index,2610,IndexRelationId) BKI_SCHEMA_MACRO
 	bool		indisready;		/* is this index ready for inserts? */
 	bool		indislive;		/* is this index alive at all? */
 	bool		indisreplident; /* is this index the identity for replication? */
+	bool		indisenabled BKI_DEFAULT(t);	/* is this index enabled for use by queries? */
 
 	/* variable-length fields start here, but we allow direct access to indkey */
 	int2vector	indkey BKI_FORCE_NOT_NULL;	/* column numbers of indexed cols,
diff --git a/src/include/nodes/parsenodes.h b/src/include/nodes/parsenodes.h
index b191eaaeca..8cf56161a5 100644
--- a/src/include/nodes/parsenodes.h
+++ b/src/include/nodes/parsenodes.h
@@ -2423,6 +2423,8 @@ typedef enum AlterTableType
 	AT_SetIdentity,				/* SET identity column options */
 	AT_DropIdentity,			/* DROP IDENTITY */
 	AT_ReAddStatistics,			/* internal to commands/tablecmds.c */
+	AT_EnableIndex,					/* ENABLE INDEX */
+	AT_DisableIndex,				/* DISABLE INDEX */
 } AlterTableType;
 
 typedef struct ReplicaIdentityStmt
@@ -3405,6 +3407,7 @@ typedef struct IndexStmt
 	bool		if_not_exists;	/* just do nothing if index already exists? */
 	bool		reset_default_tblspc;	/* reset default_tablespace prior to
 										 * executing */
+  bool		isenabled;		/* true if ENABLE (default), false if DISABLE */
 } IndexStmt;
 
 /* ----------------------
diff --git a/src/include/nodes/pathnodes.h b/src/include/nodes/pathnodes.h
index 54ee17697e..fafae771e1 100644
--- a/src/include/nodes/pathnodes.h
+++ b/src/include/nodes/pathnodes.h
@@ -1212,6 +1212,8 @@ struct IndexOptInfo
 	/* AM's cost estimator */
 	/* Rather than include amapi.h here, we declare amcostestimate like this */
 	void		(*amcostestimate) (struct PlannerInfo *, struct IndexPath *, double, Cost *, Cost *, Selectivity *, double *, double *) pg_node_attr(read_write_ignore);
+	/* true if this index is enabled */
+	bool		enabled;
 };
 
 /*
diff --git a/src/test/regress/expected/create_index.out b/src/test/regress/expected/create_index.out
index 8011c141bf..02f359b9c3 100644
--- a/src/test/regress/expected/create_index.out
+++ b/src/test/regress/expected/create_index.out
@@ -3331,6 +3331,566 @@ ERROR:  REINDEX SCHEMA cannot run inside a transaction block
 END;
 -- concurrently
 REINDEX SCHEMA CONCURRENTLY schema_to_reindex;
+-- Test enable/disable functionality for indexes
+CREATE TABLE index_test(
+    id INT PRIMARY KEY,
+    data TEXT,
+    num INT,
+    vector INT[],
+    range INT4RANGE
+);
+INSERT INTO index_test
+SELECT
+    g,
+    'data ' || g,
+    g % 100,
+    ARRAY[g, g+1, g+2],
+    int4range(g, g+10)
+FROM generate_series(1, 1000) g;
+-- Function for testing
+CREATE FUNCTION get_data_length(text) RETURNS INT AS $$
+    SELECT length($1);
+$$ LANGUAGE SQL IMMUTABLE;
+-- Helper function to show index status
+CREATE OR REPLACE FUNCTION show_index_status(index_name text)
+RETURNS TABLE (
+    indexrelid regclass,
+    indisvalid boolean,
+    indisready boolean,
+    indislive boolean,
+    indisenabled boolean
+) AS $$
+BEGIN
+    RETURN QUERY EXECUTE format('
+        SELECT indexrelid::regclass, indisvalid, indisready, indislive, indisenabled
+        FROM pg_index
+        WHERE indexrelid = %L::regclass', index_name);
+END;
+$$ LANGUAGE plpgsql;
+-- Create and test each index type
+-- 1. Basic single-column index
+CREATE INDEX idx_single ON index_test(data);
+SELECT show_index_status('idx_single');
+  show_index_status   
+----------------------
+ (idx_single,t,t,t,t)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE data = 'data 500';
+                  QUERY PLAN                   
+-----------------------------------------------
+ Bitmap Heap Scan on index_test
+   Recheck Cond: (data = 'data 500'::text)
+   ->  Bitmap Index Scan on idx_single
+         Index Cond: (data = 'data 500'::text)
+(4 rows)
+
+ALTER INDEX idx_single DISABLE;
+SELECT show_index_status('idx_single');
+  show_index_status   
+----------------------
+ (idx_single,t,t,t,f)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE data = 'data 500';
+             QUERY PLAN              
+-------------------------------------
+ Seq Scan on index_test
+   Filter: (data = 'data 500'::text)
+(2 rows)
+
+ALTER INDEX idx_single ENABLE;
+SELECT show_index_status('idx_single');
+  show_index_status   
+----------------------
+ (idx_single,t,t,t,t)
+(1 row)
+
+-- 2. Multi-column index
+CREATE INDEX idx_multi ON index_test(num, data);
+SELECT show_index_status('idx_multi');
+  show_index_status  
+---------------------
+ (idx_multi,t,t,t,t)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE num = 50 AND data > 'data 500';
+                           QUERY PLAN                           
+----------------------------------------------------------------
+ Bitmap Heap Scan on index_test
+   Recheck Cond: ((num = 50) AND (data > 'data 500'::text))
+   ->  Bitmap Index Scan on idx_multi
+         Index Cond: ((num = 50) AND (data > 'data 500'::text))
+(4 rows)
+
+ALTER INDEX idx_multi DISABLE;
+SELECT show_index_status('idx_multi');
+  show_index_status  
+---------------------
+ (idx_multi,t,t,t,f)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE num = 50 AND data > 'data 500';
+                      QUERY PLAN                      
+------------------------------------------------------
+ Seq Scan on index_test
+   Filter: ((data > 'data 500'::text) AND (num = 50))
+(2 rows)
+
+ALTER INDEX idx_multi ENABLE;
+SELECT show_index_status('idx_multi');
+  show_index_status  
+---------------------
+ (idx_multi,t,t,t,t)
+(1 row)
+
+-- 3. Partial index
+CREATE INDEX idx_partial ON index_test(num) WHERE num < 50;
+SELECT show_index_status('idx_partial');
+   show_index_status   
+-----------------------
+ (idx_partial,t,t,t,t)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE num = 25;
+               QUERY PLAN               
+----------------------------------------
+ Bitmap Heap Scan on index_test
+   Recheck Cond: (num = 25)
+   ->  Bitmap Index Scan on idx_partial
+         Index Cond: (num = 25)
+(4 rows)
+
+ALTER INDEX idx_partial DISABLE;
+SELECT show_index_status('idx_partial');
+   show_index_status   
+-----------------------
+ (idx_partial,t,t,t,f)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE num = 25;
+              QUERY PLAN              
+--------------------------------------
+ Bitmap Heap Scan on index_test
+   Recheck Cond: (num = 25)
+   ->  Bitmap Index Scan on idx_multi
+         Index Cond: (num = 25)
+(4 rows)
+
+ALTER INDEX idx_partial ENABLE;
+SELECT show_index_status('idx_partial');
+   show_index_status   
+-----------------------
+ (idx_partial,t,t,t,t)
+(1 row)
+
+-- 4. Expression index
+CREATE INDEX idx_expression ON index_test((lower(data)));
+SELECT show_index_status('idx_expression');
+    show_index_status     
+--------------------------
+ (idx_expression,t,t,t,t)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE lower(data) = 'data 500';
+                      QUERY PLAN                      
+------------------------------------------------------
+ Bitmap Heap Scan on index_test
+   Recheck Cond: (lower(data) = 'data 500'::text)
+   ->  Bitmap Index Scan on idx_expression
+         Index Cond: (lower(data) = 'data 500'::text)
+(4 rows)
+
+ALTER INDEX idx_expression DISABLE;
+SELECT show_index_status('idx_expression');
+    show_index_status     
+--------------------------
+ (idx_expression,t,t,t,f)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE lower(data) = 'data 500';
+                 QUERY PLAN                 
+--------------------------------------------
+ Seq Scan on index_test
+   Filter: (lower(data) = 'data 500'::text)
+(2 rows)
+
+ALTER INDEX idx_expression ENABLE;
+SELECT show_index_status('idx_expression');
+    show_index_status     
+--------------------------
+ (idx_expression,t,t,t,t)
+(1 row)
+
+-- 5. GIN index
+CREATE INDEX idx_gin ON index_test USING gin(vector);
+SELECT show_index_status('idx_gin');
+ show_index_status 
+-------------------
+ (idx_gin,t,t,t,t)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE vector @> ARRAY[500];
+                     QUERY PLAN                     
+----------------------------------------------------
+ Bitmap Heap Scan on index_test
+   Recheck Cond: (vector @> '{500}'::integer[])
+   ->  Bitmap Index Scan on idx_gin
+         Index Cond: (vector @> '{500}'::integer[])
+(4 rows)
+
+ALTER INDEX idx_gin DISABLE;
+SELECT show_index_status('idx_gin');
+ show_index_status 
+-------------------
+ (idx_gin,t,t,t,f)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE vector @> ARRAY[500];
+                QUERY PLAN                
+------------------------------------------
+ Seq Scan on index_test
+   Filter: (vector @> '{500}'::integer[])
+(2 rows)
+
+ALTER INDEX idx_gin ENABLE;
+SELECT show_index_status('idx_gin');
+ show_index_status 
+-------------------
+ (idx_gin,t,t,t,t)
+(1 row)
+
+-- 6. GiST index
+CREATE INDEX idx_gist ON index_test USING gist(range);
+SELECT show_index_status('idx_gist');
+ show_index_status  
+--------------------
+ (idx_gist,t,t,t,t)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE range && int4range(100, 110);
+                      QUERY PLAN                       
+-------------------------------------------------------
+ Bitmap Heap Scan on index_test
+   Recheck Cond: (range && '[100,110)'::int4range)
+   ->  Bitmap Index Scan on idx_gist
+         Index Cond: (range && '[100,110)'::int4range)
+(4 rows)
+
+ALTER INDEX idx_gist DISABLE;
+SELECT show_index_status('idx_gist');
+ show_index_status  
+--------------------
+ (idx_gist,t,t,t,f)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE range && int4range(100, 110);
+                 QUERY PLAN                  
+---------------------------------------------
+ Seq Scan on index_test
+   Filter: (range && '[100,110)'::int4range)
+(2 rows)
+
+ALTER INDEX idx_gist ENABLE;
+SELECT show_index_status('idx_gist');
+ show_index_status  
+--------------------
+ (idx_gist,t,t,t,t)
+(1 row)
+
+-- 7. Covering index
+CREATE INDEX idx_covering ON index_test(num) INCLUDE (data);
+SELECT show_index_status('idx_covering');
+   show_index_status    
+------------------------
+ (idx_covering,t,t,t,t)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT num, data FROM index_test WHERE num = 50;
+               QUERY PLAN                
+-----------------------------------------
+ Bitmap Heap Scan on index_test
+   Recheck Cond: (num = 50)
+   ->  Bitmap Index Scan on idx_covering
+         Index Cond: (num = 50)
+(4 rows)
+
+ALTER INDEX idx_covering DISABLE;
+SELECT show_index_status('idx_covering');
+   show_index_status    
+------------------------
+ (idx_covering,t,t,t,f)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT num, data FROM index_test WHERE num = 50;
+              QUERY PLAN              
+--------------------------------------
+ Bitmap Heap Scan on index_test
+   Recheck Cond: (num = 50)
+   ->  Bitmap Index Scan on idx_multi
+         Index Cond: (num = 50)
+(4 rows)
+
+ALTER INDEX idx_covering ENABLE;
+SELECT show_index_status('idx_covering');
+   show_index_status    
+------------------------
+ (idx_covering,t,t,t,t)
+(1 row)
+
+-- 8. Unique index
+CREATE UNIQUE INDEX idx_unique ON index_test(id, data);
+SELECT show_index_status('idx_unique');
+  show_index_status   
+----------------------
+ (idx_unique,t,t,t,t)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE id = 500 AND data = 'data 500';
+                        QUERY PLAN                        
+----------------------------------------------------------
+ Index Scan using idx_unique on index_test
+   Index Cond: ((id = 500) AND (data = 'data 500'::text))
+(2 rows)
+
+ALTER INDEX idx_unique DISABLE;
+SELECT show_index_status('idx_unique');
+  show_index_status   
+----------------------
+ (idx_unique,t,t,t,f)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE id = 500 AND data = 'data 500';
+                   QUERY PLAN                   
+------------------------------------------------
+ Index Scan using index_test_pkey on index_test
+   Index Cond: (id = 500)
+   Filter: (data = 'data 500'::text)
+(3 rows)
+
+ALTER INDEX idx_unique ENABLE;
+SELECT show_index_status('idx_unique');
+  show_index_status   
+----------------------
+ (idx_unique,t,t,t,t)
+(1 row)
+
+-- 9. Function-based index
+CREATE INDEX idx_func ON index_test(get_data_length(data));
+SELECT show_index_status('idx_func');
+ show_index_status  
+--------------------
+ (idx_func,t,t,t,t)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE get_data_length(data) = 10;
+               QUERY PLAN                
+-----------------------------------------
+ Bitmap Heap Scan on index_test
+   Recheck Cond: (length(data) = 10)
+   ->  Bitmap Index Scan on idx_func
+         Index Cond: (length(data) = 10)
+(4 rows)
+
+ALTER INDEX idx_func DISABLE;
+SELECT show_index_status('idx_func');
+ show_index_status  
+--------------------
+ (idx_func,t,t,t,f)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE get_data_length(data) = 10;
+          QUERY PLAN           
+-------------------------------
+ Seq Scan on index_test
+   Filter: (length(data) = 10)
+(2 rows)
+
+ALTER INDEX idx_func ENABLE;
+SELECT show_index_status('idx_func');
+ show_index_status  
+--------------------
+ (idx_func,t,t,t,t)
+(1 row)
+
+-- 10. Join index
+CREATE TABLE join_test (id INT PRIMARY KEY, ref_id INT);
+INSERT INTO join_test SELECT g, g % 100 FROM generate_series(1, 1000) g;
+CREATE INDEX idx_join ON join_test(ref_id);
+SELECT show_index_status('idx_join');
+ show_index_status  
+--------------------
+ (idx_join,t,t,t,t)
+(1 row)
+
+EXPLAIN (COSTS OFF)
+SELECT jt.id, it.data
+FROM join_test jt
+JOIN index_test it ON jt.ref_id = it.num
+WHERE jt.id BETWEEN 100 AND 200;
+                          QUERY PLAN                           
+---------------------------------------------------------------
+ Hash Join
+   Hash Cond: (it.num = jt.ref_id)
+   ->  Seq Scan on index_test it
+   ->  Hash
+         ->  Bitmap Heap Scan on join_test jt
+               Recheck Cond: ((id >= 100) AND (id <= 200))
+               ->  Bitmap Index Scan on join_test_pkey
+                     Index Cond: ((id >= 100) AND (id <= 200))
+(8 rows)
+
+-- Disable all indexes to force seq scan
+ALTER INDEX idx_join DISABLE;
+ALTER INDEX join_test_pkey DISABLE;
+SELECT show_index_status('idx_join');
+ show_index_status  
+--------------------
+ (idx_join,t,t,t,f)
+(1 row)
+
+SELECT show_index_status('join_test_pkey');
+    show_index_status     
+--------------------------
+ (join_test_pkey,t,t,t,f)
+(1 row)
+
+EXPLAIN (COSTS OFF)
+SELECT jt.id, it.data
+FROM join_test jt
+JOIN index_test it ON jt.ref_id = it.num
+WHERE jt.id BETWEEN 100 AND 200;
+                     QUERY PLAN                      
+-----------------------------------------------------
+ Hash Join
+   Hash Cond: (it.num = jt.ref_id)
+   ->  Seq Scan on index_test it
+   ->  Hash
+         ->  Seq Scan on join_test jt
+               Filter: ((id >= 100) AND (id <= 200))
+(6 rows)
+
+ALTER INDEX idx_join ENABLE;
+ALTER INDEX join_test_pkey ENABLE;
+SELECT show_index_status('idx_join');
+ show_index_status  
+--------------------
+ (idx_join,t,t,t,t)
+(1 row)
+
+SELECT show_index_status('join_test_pkey');
+    show_index_status     
+--------------------------
+ (join_test_pkey,t,t,t,t)
+(1 row)
+
+-- Test REINDEX CONCURRENTLY
+REINDEX INDEX CONCURRENTLY idx_join;
+SELECT show_index_status('idx_join');
+ show_index_status  
+--------------------
+ (idx_join,t,t,t,t)
+(1 row)
+
+ALTER INDEX idx_join DISABLE;
+SELECT show_index_status('idx_join');
+ show_index_status  
+--------------------
+ (idx_join,t,t,t,f)
+(1 row)
+
+REINDEX INDEX CONCURRENTLY idx_join;
+SELECT show_index_status('idx_join');
+ show_index_status  
+--------------------
+ (idx_join,t,t,t,f)
+(1 row)
+
+SELECT pg_get_indexdef('idx_join'::regclass);
+                                  pg_get_indexdef                                  
+-----------------------------------------------------------------------------------
+ CREATE INDEX idx_join ON schema_to_reindex.join_test USING btree (ref_id) DISABLE
+(1 row)
+
+ALTER INDEX idx_join ENABLE;
+SELECT pg_get_indexdef('idx_join'::regclass);
+                              pg_get_indexdef                              
+---------------------------------------------------------------------------
+ CREATE INDEX idx_join ON schema_to_reindex.join_test USING btree (ref_id)
+(1 row)
+
+-- Test enable/disable index with indcheckxmin being true
+CREATE TABLE indcheckxmin_test(id int PRIMARY KEY);
+INSERT INTO indcheckxmin_test VALUES (1), (2), (3);
+CREATE INDEX CONCURRENTLY idx_checkxmin ON indcheckxmin_test(id);
+BEGIN;
+-- Simulate indcheckxmin being true
+UPDATE pg_index SET indcheckxmin = true WHERE indexrelid = 'idx_checkxmin'::regclass;
+ALTER INDEX idx_checkxmin DISABLE;  -- expect fail
+ERROR:  cannot enable/disable index while indcheckxmin is true
+HINT:  Wait for all transactions that might see inconsistent HOT chains to complete
+ROLLBACK;
+-- Test prepared statements with enabled/disabled indexes
+CREATE TABLE prep_idx_test (id int, data text);
+CREATE INDEX prep_idx1 ON prep_idx_test(data);
+INSERT INTO prep_idx_test SELECT g, 'data ' || g FROM generate_series(1,100) g;
+-- Test with enabled index
+PREPARE idx_plan AS SELECT * FROM prep_idx_test WHERE data = $1;
+EXPLAIN (COSTS OFF) EXECUTE idx_plan('data 1');
+                 QUERY PLAN                  
+---------------------------------------------
+ Bitmap Heap Scan on prep_idx_test
+   Recheck Cond: (data = 'data 1'::text)
+   ->  Bitmap Index Scan on prep_idx1
+         Index Cond: (data = 'data 1'::text)
+(4 rows)
+
+EXECUTE idx_plan('data 1');
+ id |  data  
+----+--------
+  1 | data 1
+(1 row)
+
+-- Test with disabled index
+ALTER INDEX prep_idx1 DISABLE;
+EXPLAIN (COSTS OFF) EXECUTE idx_plan('data 1');
+            QUERY PLAN             
+-----------------------------------
+ Seq Scan on prep_idx_test
+   Filter: (data = 'data 1'::text)
+(2 rows)
+
+EXECUTE idx_plan('data 1');
+ id |  data  
+----+--------
+  1 | data 1
+(1 row)
+
+-- Re-enable and test again
+ALTER INDEX prep_idx1 ENABLE;
+EXPLAIN (COSTS OFF) EXECUTE idx_plan('data 1');
+                 QUERY PLAN                  
+---------------------------------------------
+ Bitmap Heap Scan on prep_idx_test
+   Recheck Cond: (data = 'data 1'::text)
+   ->  Bitmap Index Scan on prep_idx1
+         Index Cond: (data = 'data 1'::text)
+(4 rows)
+
+EXECUTE idx_plan('data 1');
+ id |  data  
+----+--------
+  1 | data 1
+(1 row)
+
+-- Clean up
+DROP TABLE index_test;
+DROP TABLE join_test;
+DROP FUNCTION get_data_length;
+DROP FUNCTION show_index_status;
+DROP TABLE indcheckxmin_test CASCADE;
+DEALLOCATE idx_plan;
+DROP TABLE prep_idx_test;
 -- Failure for unauthorized user
 CREATE ROLE regress_reindexuser NOLOGIN;
 SET SESSION ROLE regress_reindexuser;
diff --git a/src/test/regress/sql/create_index.sql b/src/test/regress/sql/create_index.sql
index 068c66b95a..4db53996cd 100644
--- a/src/test/regress/sql/create_index.sql
+++ b/src/test/regress/sql/create_index.sql
@@ -1415,6 +1415,220 @@ END;
 -- concurrently
 REINDEX SCHEMA CONCURRENTLY schema_to_reindex;
 
+-- Test enable/disable functionality for indexes
+
+CREATE TABLE index_test(
+    id INT PRIMARY KEY,
+    data TEXT,
+    num INT,
+    vector INT[],
+    range INT4RANGE
+);
+
+INSERT INTO index_test
+SELECT
+    g,
+    'data ' || g,
+    g % 100,
+    ARRAY[g, g+1, g+2],
+    int4range(g, g+10)
+FROM generate_series(1, 1000) g;
+
+-- Function for testing
+CREATE FUNCTION get_data_length(text) RETURNS INT AS $$
+    SELECT length($1);
+$$ LANGUAGE SQL IMMUTABLE;
+
+-- Helper function to show index status
+CREATE OR REPLACE FUNCTION show_index_status(index_name text)
+RETURNS TABLE (
+    indexrelid regclass,
+    indisvalid boolean,
+    indisready boolean,
+    indislive boolean,
+    indisenabled boolean
+) AS $$
+BEGIN
+    RETURN QUERY EXECUTE format('
+        SELECT indexrelid::regclass, indisvalid, indisready, indislive, indisenabled
+        FROM pg_index
+        WHERE indexrelid = %L::regclass', index_name);
+END;
+$$ LANGUAGE plpgsql;
+
+-- Create and test each index type
+-- 1. Basic single-column index
+CREATE INDEX idx_single ON index_test(data);
+SELECT show_index_status('idx_single');
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE data = 'data 500';
+ALTER INDEX idx_single DISABLE;
+SELECT show_index_status('idx_single');
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE data = 'data 500';
+ALTER INDEX idx_single ENABLE;
+SELECT show_index_status('idx_single');
+
+-- 2. Multi-column index
+CREATE INDEX idx_multi ON index_test(num, data);
+SELECT show_index_status('idx_multi');
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE num = 50 AND data > 'data 500';
+ALTER INDEX idx_multi DISABLE;
+SELECT show_index_status('idx_multi');
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE num = 50 AND data > 'data 500';
+ALTER INDEX idx_multi ENABLE;
+SELECT show_index_status('idx_multi');
+
+-- 3. Partial index
+CREATE INDEX idx_partial ON index_test(num) WHERE num < 50;
+SELECT show_index_status('idx_partial');
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE num = 25;
+ALTER INDEX idx_partial DISABLE;
+SELECT show_index_status('idx_partial');
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE num = 25;
+ALTER INDEX idx_partial ENABLE;
+SELECT show_index_status('idx_partial');
+
+-- 4. Expression index
+CREATE INDEX idx_expression ON index_test((lower(data)));
+SELECT show_index_status('idx_expression');
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE lower(data) = 'data 500';
+ALTER INDEX idx_expression DISABLE;
+SELECT show_index_status('idx_expression');
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE lower(data) = 'data 500';
+ALTER INDEX idx_expression ENABLE;
+SELECT show_index_status('idx_expression');
+
+-- 5. GIN index
+CREATE INDEX idx_gin ON index_test USING gin(vector);
+SELECT show_index_status('idx_gin');
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE vector @> ARRAY[500];
+ALTER INDEX idx_gin DISABLE;
+SELECT show_index_status('idx_gin');
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE vector @> ARRAY[500];
+ALTER INDEX idx_gin ENABLE;
+SELECT show_index_status('idx_gin');
+
+-- 6. GiST index
+CREATE INDEX idx_gist ON index_test USING gist(range);
+SELECT show_index_status('idx_gist');
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE range && int4range(100, 110);
+ALTER INDEX idx_gist DISABLE;
+SELECT show_index_status('idx_gist');
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE range && int4range(100, 110);
+ALTER INDEX idx_gist ENABLE;
+SELECT show_index_status('idx_gist');
+
+-- 7. Covering index
+CREATE INDEX idx_covering ON index_test(num) INCLUDE (data);
+SELECT show_index_status('idx_covering');
+EXPLAIN (COSTS OFF) SELECT num, data FROM index_test WHERE num = 50;
+ALTER INDEX idx_covering DISABLE;
+SELECT show_index_status('idx_covering');
+EXPLAIN (COSTS OFF) SELECT num, data FROM index_test WHERE num = 50;
+ALTER INDEX idx_covering ENABLE;
+SELECT show_index_status('idx_covering');
+
+-- 8. Unique index
+CREATE UNIQUE INDEX idx_unique ON index_test(id, data);
+SELECT show_index_status('idx_unique');
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE id = 500 AND data = 'data 500';
+ALTER INDEX idx_unique DISABLE;
+SELECT show_index_status('idx_unique');
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE id = 500 AND data = 'data 500';
+ALTER INDEX idx_unique ENABLE;
+SELECT show_index_status('idx_unique');
+
+-- 9. Function-based index
+CREATE INDEX idx_func ON index_test(get_data_length(data));
+SELECT show_index_status('idx_func');
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE get_data_length(data) = 10;
+ALTER INDEX idx_func DISABLE;
+SELECT show_index_status('idx_func');
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE get_data_length(data) = 10;
+ALTER INDEX idx_func ENABLE;
+SELECT show_index_status('idx_func');
+
+-- 10. Join index
+CREATE TABLE join_test (id INT PRIMARY KEY, ref_id INT);
+INSERT INTO join_test SELECT g, g % 100 FROM generate_series(1, 1000) g;
+CREATE INDEX idx_join ON join_test(ref_id);
+SELECT show_index_status('idx_join');
+
+EXPLAIN (COSTS OFF)
+SELECT jt.id, it.data
+FROM join_test jt
+JOIN index_test it ON jt.ref_id = it.num
+WHERE jt.id BETWEEN 100 AND 200;
+
+-- Disable all indexes to force seq scan
+ALTER INDEX idx_join DISABLE;
+ALTER INDEX join_test_pkey DISABLE;
+SELECT show_index_status('idx_join');
+SELECT show_index_status('join_test_pkey');
+
+EXPLAIN (COSTS OFF)
+SELECT jt.id, it.data
+FROM join_test jt
+JOIN index_test it ON jt.ref_id = it.num
+WHERE jt.id BETWEEN 100 AND 200;
+
+ALTER INDEX idx_join ENABLE;
+ALTER INDEX join_test_pkey ENABLE;
+SELECT show_index_status('idx_join');
+SELECT show_index_status('join_test_pkey');
+
+-- Test REINDEX CONCURRENTLY
+REINDEX INDEX CONCURRENTLY idx_join;
+SELECT show_index_status('idx_join');
+
+ALTER INDEX idx_join DISABLE;
+SELECT show_index_status('idx_join');
+REINDEX INDEX CONCURRENTLY idx_join;
+SELECT show_index_status('idx_join');
+
+SELECT pg_get_indexdef('idx_join'::regclass);
+ALTER INDEX idx_join ENABLE;
+SELECT pg_get_indexdef('idx_join'::regclass);
+
+-- Test enable/disable index with indcheckxmin being true
+
+CREATE TABLE indcheckxmin_test(id int PRIMARY KEY);
+INSERT INTO indcheckxmin_test VALUES (1), (2), (3);
+CREATE INDEX CONCURRENTLY idx_checkxmin ON indcheckxmin_test(id);
+BEGIN;
+-- Simulate indcheckxmin being true
+UPDATE pg_index SET indcheckxmin = true WHERE indexrelid = 'idx_checkxmin'::regclass;
+ALTER INDEX idx_checkxmin DISABLE;  -- expect fail
+ROLLBACK;
+
+-- Test prepared statements with enabled/disabled indexes
+CREATE TABLE prep_idx_test (id int, data text);
+CREATE INDEX prep_idx1 ON prep_idx_test(data);
+INSERT INTO prep_idx_test SELECT g, 'data ' || g FROM generate_series(1,100) g;
+
+-- Test with enabled index
+PREPARE idx_plan AS SELECT * FROM prep_idx_test WHERE data = $1;
+EXPLAIN (COSTS OFF) EXECUTE idx_plan('data 1');
+EXECUTE idx_plan('data 1');
+
+-- Test with disabled index
+ALTER INDEX prep_idx1 DISABLE;
+EXPLAIN (COSTS OFF) EXECUTE idx_plan('data 1');
+EXECUTE idx_plan('data 1');
+
+-- Re-enable and test again
+ALTER INDEX prep_idx1 ENABLE;
+EXPLAIN (COSTS OFF) EXECUTE idx_plan('data 1');
+EXECUTE idx_plan('data 1');
+
+-- Clean up
+DROP TABLE index_test;
+DROP TABLE join_test;
+DROP FUNCTION get_data_length;
+DROP FUNCTION show_index_status;
+DROP TABLE indcheckxmin_test CASCADE;
+DEALLOCATE idx_plan;
+DROP TABLE prep_idx_test;
+
 -- Failure for unauthorized user
 CREATE ROLE regress_reindexuser NOLOGIN;
 SET SESSION ROLE regress_reindexuser;
-- 
2.39.5 (Apple Git-154)

#59Sami Imseih
samimseih@gmail.com
In reply to: Shayon Mukherjee (#58)
Re: Proposal to Enable/Disable Index using ALTER INDEX (with patch)

Thanks for the updates patch!

This got me thinking if dropping the index is the only
use case we really care about. For example, you may want
to prevent an index that is enforcing a constraint from
being used by the planner, but you probably don't want to
drop it. In fact, I also think that you may want the index
from being used in one part of your application but could
potentially benefit other parts of your application. In that
case, I can see a GUC that allows you to force the use of a
an index that has been CREATED or ALTERED as DISABLED.
UNlike the GUC suggested earlier in the thread, this GUC
can simply be a boolean to allow the force usage of a
DISABLED index. FWIW, Oracle has a similar parameter called
OPTIMIZER_USE_INVISIBLE_INDEXES.

I totally see where you are coming from. Some rough thoughts/notes:

- The patch/proposed feature today doesn't disable constraints, like uniqueness. It only impacts query planning. Maybe it should ?
- I was imagining this feature as being short-lived in production - that is, you disable a potential index to collect data on query performance and then make a decision on whether you need the index permanently. However, yes, one can always keep an index disabled for longer, and conditionally use it in another part of an application in which case a GUC to bypass the disabled/invisible index would come in handy as you mentioned.
- I don't have a strong opinion either way, but I do wonder - considering that this GUC is an additive feature - if it's something worth implementing once we have more feedback from the usage (in v18 pre release, alpha, ec) of marking an index as disabled/invisible first? Or perhaps as a follow-up patch?

If we do go with a GUC - is FORCE_INVISIBLE_INDEX a good name?

Here is a use-case where the GUC may be useful. I can see a user
wanting to try out the index before committing to using it across the
board. They can create the index as invisible and force using
it in a specific part of the application. If they are happy with the results,
they can make it visible. This is similar to but not exactly what HypoPG [1]https://github.com/HypoPG/hypopg
does. HypoPG does not actually create the index and can only be used
with EXPLAIN ( not EXPLAIN ANALYZE ) in a specific session. I see the
ability to test on a real index may be more useful. Maybe others have
other thoughts on this?

I agree. DISABLE doesn't sit right. I noticed INVISIBLE in MariaDB. I like HIDDEN/VISIBLE or ACTIVE/INACTIVE as well, since it impacts query planning.

Let's see if other have an opinion on this, but VISIBLE/INVISIBLE
seem the best way to indicate that the indexes are visible or invisible
from the optimizer. ACTIVE/INACTIVE sound a lot like ENABLE/DISABLE.

[1]: https://github.com/HypoPG/hypopg

Regards,

Sami

#60Shayon Mukherjee
shayonj@gmail.com
In reply to: Sami Imseih (#59)
1 attachment(s)
Re: Proposal to Enable/Disable Index using ALTER INDEX (with patch)

On Sat, Jan 11, 2025 at 5:50 PM Sami Imseih <samimseih@gmail.com> wrote:

Here is a use-case where the GUC may be useful. I can see a user
wanting to try out the index before committing to using it across the
board. They can create the index as invisible and force using
it in a specific part of the application. If they are happy with the
results,
they can make it visible. This is similar to but not exactly what HypoPG
[1]
does. HypoPG does not actually create the index and can only be used
with EXPLAIN ( not EXPLAIN ANALYZE ) in a specific session. I see the
ability to test on a real index may be more useful. Maybe others have
other thoughts on this?

That's a good call out, thank you. I was mostly interested in the other use
cases and I like how this bool GUC unlocks the use case you mentioned.
Plus, also the ability to conditionally use indexes in session that are
globally marked as invisible.

I agree. DISABLE doesn't sit right. I noticed INVISIBLE in MariaDB. I

like HIDDEN/VISIBLE or ACTIVE/INACTIVE as well, since it impacts query
planning.

Let's see if other have an opinion on this, but VISIBLE/INVISIBLE
seem the best way to indicate that the indexes are visible or invisible
from the optimizer. ACTIVE/INACTIVE sound a lot like ENABLE/DISABLE.

I like VISIBLE/INVISIBLE. Proposing a new patch with the following changes

- We now have moved away from DISABLE/ENABLE grammar to VISIBLE/INVISIBLE.
No change in functionality, it's all the same as before, just new grammar.
Backed by regression specs like before too.
- The column in pg_index is now called indisvisible.
- Introduced a new GUC - use_invisible_index. When set to on, it will not
respect the visibility state in pg_index (related to the above
conversation).
- When GUC is assigned/updated we accordingly reset plan cache. Backed this
specs with.

The patch is rebased against master and passes in CI. Happy to iterate on
any feedback received.

Thanks
Shayon

Attachments:

v9-0001-Introduce-the-ability-to-set-index-visibility-usi.patchapplication/octet-stream; name=v9-0001-Introduce-the-ability-to-set-index-visibility-usi.patchDownload
From 6445a66940857c842ff00f8aefee17efc911a76e Mon Sep 17 00:00:00 2001
From: Shayon Mukherjee <shayonj@gmail.com>
Date: Sun, 12 Jan 2025 14:34:48 -0500
Subject: [PATCH v9] Introduce the ability to set index visibility using ALTER
 INDEX

This patch introduces index visibility control using ALTER INDEX and CREATE INDEX
commands.

Original motivation for the problem and proposal for a patch
can be found at [1].

This patch passes all the existing specs and the newly added regression tests. The patch
is ready for review and test. It compiles, so the patch can be applied for testing as well.

Note: The patch has gone through a few iterations. Earlier versions of the patch had the ENABLE/DISABLE grammar.
The current version has the VISIBLE/INVISIBLE grammar. So, you will the local variable names using the new grammar accordingly.

Implementation details:

- New Grammar:
  * ALTER INDEX ... VISIBLE/INVISIBLE
  * CREATE INDEX ... INVISIBLE

- Default state is visible. Indexes are only invisible when explicitly
  instructed via CREATE INDEX ... INVISIBLE or ALTER INDEX ... INVISIBLE.

- Primary Key and Unique constraint indexes are always visible. The
  VISIBLE/INVISIBLE grammar is supported for these types of indexes and they can
  be made invisible via ALTER INDEX ... INVISIBLE.

- ALTER INDEX ... VISIBLE/INVISIBLE performs update on the relevant row in pg_index
  catalog

- pg_get_indexdef() supports the new functionality and grammar. This change is
  reflected in \d output for tables and pg_dump. We show the INVISIBLE syntax accordingly.

- Added force_invisible_index GUC parameter that forces the planner to use invisible
  indexes. This is useful for testing and validating index behavior without changing
  their visibility state. Based on feedback from Sami S [2]

- Updated create_index.sql regression test to cover the new grammar and verify
  that invisible indexes are not used in queries. The test covers:

  - Basic single-column and multi-column indexes
  - Partial indexes
  - Expression indexes
  - Join indexes
  - GIN and GiST indexes
  - Covering indexes
  - Range indexes
  - Unique indexes and constraints

- Adds a new indisvisible attribute to the IndexOptInfo structure.

- Modifies get_relation_info in plancat.c to skip invisible indexes entirely, thus reducing the number of places we need to check if an index is invisible or not. Inspired by the conversations start at [3].
  - I chose to modify the logic within get_relation_info as compared to, say, reducing the cost to make the planner not consider an index during planning, mostly to keep the number of changes being introduced to a minimum and also the logic itself being self-contained and easier to understand perhaps (?).

- No changes are made to stop the index from getting maintained. This way we ensure no
  data loss or corruption when index is made visible again.

- TOAST indexes are supported and visible by default as well.

- REINDEX CONCURRENTLY is supported as well and existing state of pg_index.indisvisible
  is carried over accordingly.

- See the changes in create_index.sql to get an idea of the grammar and sql statements.

- See the changes in create_index.out to get an idea of the catalogue states and EXPLAIN
  output to see when an index is getting used or isn't (when invisible).

- Incorporated DavidR's feedback from [4] around documentation and also you will see that by skipping invisible indexes entirely from get_relation_info in plancat.c (as mentioned above), we address the other mentioned issues as well.

- Lastly, protects against the case where indcheckxmin is true by raising ERRCODE_OBJECT_NOT_IN_PREREQUISITE_STATE.

Looking forward to any and all feedback on this patch, including but not limited to code quality, tests, fundamental logic.

[1] https://www.postgresql.org/message-id/CANqtF-oXKe0M%3D0QOih6H%2BsZRjE2BWAbkW_1%2B9nMEAMLxUJg5jA%40mail.gmail.com
[2] https://www.postgresql.org/message-id/CAA5RZ0udzydObMDi65C59-oq54B9ZmjSZ1wVH3h%2Bv4XiVm6QDA%40mail.gmail.com
[3] https://www.postgresql.org/message-id/3465209.1727202064%40sss.pgh.pa.us
[4] https://www.postgresql.org/message-id/CAApHDvpUNu%3DiVcdJ74sypvgeaCF%2Btfpyb8VRhZaF7DTd1xVr7g%40mail.gmail.com
---
 doc/src/sgml/catalogs.sgml                 |  11 +
 doc/src/sgml/config.sgml                   |  16 +
 doc/src/sgml/ref/alter_index.sgml          |  39 ++
 doc/src/sgml/ref/create_index.sgml         |  29 +
 src/backend/bootstrap/bootparse.y          |   2 +
 src/backend/catalog/index.c                |  31 +-
 src/backend/catalog/toasting.c             |   2 +-
 src/backend/commands/indexcmds.c           |   4 +
 src/backend/commands/tablecmds.c           |  72 ++-
 src/backend/optimizer/util/plancat.c       |  31 +-
 src/backend/parser/gram.y                  |  56 +-
 src/backend/parser/parse_utilcmd.c         |   3 +
 src/backend/utils/adt/ruleutils.c          |   4 +
 src/backend/utils/cache/relcache.c         |   1 +
 src/backend/utils/misc/guc_tables.c        |  11 +
 src/include/catalog/index.h                |   2 +-
 src/include/catalog/pg_index.h             |   1 +
 src/include/nodes/parsenodes.h             |   3 +
 src/include/optimizer/optimizer.h          |   5 +
 src/include/parser/kwlist.h                |   2 +
 src/include/utils/guc_hooks.h              |   1 +
 src/test/regress/expected/create_index.out | 586 +++++++++++++++++++++
 src/test/regress/sql/create_index.sql      | 222 ++++++++
 23 files changed, 1115 insertions(+), 19 deletions(-)

diff --git a/doc/src/sgml/catalogs.sgml b/doc/src/sgml/catalogs.sgml
index 238ed67919..e8ce2a20bc 100644
--- a/doc/src/sgml/catalogs.sgml
+++ b/doc/src/sgml/catalogs.sgml
@@ -4595,6 +4595,17 @@ SCRAM-SHA-256$<replaceable>&lt;iteration count&gt;</replaceable>:<replaceable>&l
        partial index.
       </para></entry>
      </row>
+
+     <row>
+      <entry role="catalog_table_entry"><para role="column_definition">
+       <structfield>indisvisible</structfield> <type>bool</type>
+      </para>
+      <para>
+       If true, the index is currently visible to the planner and may be used for queries.
+       If false, the index is invisible and may not be used for queries,
+       but is still updated when the table is modified. Default is true.
+      </para></entry>
+     </row>
     </tbody>
    </tgroup>
   </table>
diff --git a/doc/src/sgml/config.sgml b/doc/src/sgml/config.sgml
index 3f41a17b1f..664323d309 100644
--- a/doc/src/sgml/config.sgml
+++ b/doc/src/sgml/config.sgml
@@ -5588,6 +5588,22 @@ ANY <replaceable class="parameter">num_sync</replaceable> ( <replaceable class="
       </listitem>
      </varlistentry>
 
+     <varlistentry id="guc-force-invisible-index" xreflabel="use_invisible_index">
+      <term><varname>use_invisible_index</varname> (<type>boolean</type>)
+      <indexterm>
+       <primary><varname>use_invisible_index</varname> configuration parameter</primary>
+      </indexterm>
+      </term>
+      <listitem>
+       <para>
+        Forces the query planner to consider indexes that have been marked as invisible using
+        <command>ALTER INDEX ... INVISIBLE</command>. This parameter is useful for selective
+        use of invisible indexes in specific application contexts. The default
+        is <literal>off</literal>.
+       </para>
+      </listitem>
+     </varlistentry>
+
      </variablelist>
      </sect2>
      <sect2 id="runtime-config-query-constants">
diff --git a/doc/src/sgml/ref/alter_index.sgml b/doc/src/sgml/ref/alter_index.sgml
index 1d42d05d85..2c596b6027 100644
--- a/doc/src/sgml/ref/alter_index.sgml
+++ b/doc/src/sgml/ref/alter_index.sgml
@@ -31,6 +31,8 @@ ALTER INDEX [ IF EXISTS ] <replaceable class="parameter">name</replaceable> ALTE
     SET STATISTICS <replaceable class="parameter">integer</replaceable>
 ALTER INDEX ALL IN TABLESPACE <replaceable class="parameter">name</replaceable> [ OWNED BY <replaceable class="parameter">role_name</replaceable> [, ... ] ]
     SET TABLESPACE <replaceable class="parameter">new_tablespace</replaceable> [ NOWAIT ]
+ALTER INDEX [ IF EXISTS ] <replaceable class="parameter">name</replaceable> VISIBLE
+ALTER INDEX [ IF EXISTS ] <replaceable class="parameter">name</replaceable> INVISIBLE
 </synopsis>
  </refsynopsisdiv>
 
@@ -159,6 +161,29 @@ ALTER INDEX ALL IN TABLESPACE <replaceable class="parameter">name</replaceable>
     </listitem>
    </varlistentry>
 
+   <varlistentry>
+    <term><literal>VISIBLE</literal></term>
+    <listitem>
+     <para>
+      Make the specified index visible. The index will be used for queries.
+     </para>
+    </listitem>
+   </varlistentry>
+
+   <varlistentry>
+    <term><literal>INVISIBLE</literal></term>
+    <listitem>
+     <para>
+      Make the specified index invisible. The index will not be used for queries.
+      This can be useful for testing query performance with and without specific
+      indexes. If performance degrades after making an index invisible, it can be easily
+      be made visible using <literal>VISIBLE</literal>. Before making an index invisible, it's recommended
+      to check <structname>pg_stat_user_indexes</structname>.<structfield>idx_scan</structfield>
+      to identify potentially unused indexes.
+     </para>
+    </listitem>
+   </varlistentry>
+
   </variablelist>
   </para>
 
@@ -301,6 +326,20 @@ CREATE INDEX coord_idx ON measured (x, y, (z + t));
 ALTER INDEX coord_idx ALTER COLUMN 3 SET STATISTICS 1000;
 </programlisting></para>
 
+  <para>
+   To make an index visible:
+<programlisting>
+ALTER INDEX idx_name VISIBLE;
+</programlisting>
+  </para>
+
+  <para>
+   To make an index invisible:
+<programlisting>
+ALTER INDEX idx_name INVISIBLE;
+</programlisting>
+  </para>
+
  </refsect1>
 
  <refsect1>
diff --git a/doc/src/sgml/ref/create_index.sgml b/doc/src/sgml/ref/create_index.sgml
index 208389e800..90d7d90a2b 100644
--- a/doc/src/sgml/ref/create_index.sgml
+++ b/doc/src/sgml/ref/create_index.sgml
@@ -28,6 +28,7 @@ CREATE [ UNIQUE ] INDEX [ CONCURRENTLY ] [ [ IF NOT EXISTS ] <replaceable class=
     [ WITH ( <replaceable class="parameter">storage_parameter</replaceable> [= <replaceable class="parameter">value</replaceable>] [, ... ] ) ]
     [ TABLESPACE <replaceable class="parameter">tablespace_name</replaceable> ]
     [ WHERE <replaceable class="parameter">predicate</replaceable> ]
+    [ INVISIBLE ]
 </synopsis>
  </refsynopsisdiv>
 
@@ -380,6 +381,19 @@ CREATE [ UNIQUE ] INDEX [ CONCURRENTLY ] [ [ IF NOT EXISTS ] <replaceable class=
       </listitem>
      </varlistentry>
 
+    <varlistentry>
+      <term><literal>INVISIBLE</literal></term>
+      <listitem>
+       <para>
+        Creates the index in an invisible state (default visible). An invisible index is
+        not used by the query planner for queries, but it is still maintained
+        when the underlying table data changes. This can be useful when you want to create
+        an index without immediately impacting query planning, allowing you to make it
+        visible later at a more convenient time. The index can be made visible later
+        using <command>ALTER INDEX ... VISIBLE</command>.
+       </para>
+      </listitem>
+     </varlistentry>
     </variablelist>
 
   <refsect2 id="sql-createindex-storage-parameters" xreflabel="Index Storage Parameters">
@@ -701,6 +715,14 @@ Indexes:
     partitioned index is a metadata only operation.
    </para>
 
+  <para>
+   When creating an index with the <literal>INVISIBLE</literal> option, the index
+   will be created but not used for query planning. This can be useful for
+   preparing an index in advance of its use, or for testing purposes. The index
+   will still be maintained as the table is modified, so it can be made visible
+   later without needing to be rebuilt. By default all new indexes are visible.
+  </para>
+
   </refsect2>
  </refsect1>
 
@@ -980,6 +1002,13 @@ SELECT * FROM points
 CREATE INDEX CONCURRENTLY sales_quantity_index ON sales_table (quantity);
 </programlisting></para>
 
+  <para>
+   To create an index on the table <literal>test_table</literal> with the default
+   name, but have it initially invisible:
+<programlisting>
+CREATE INDEX ON test_table (col1) INVISIBLE;
+</programlisting>
+  </para>
  </refsect1>
 
  <refsect1>
diff --git a/src/backend/bootstrap/bootparse.y b/src/backend/bootstrap/bootparse.y
index 9833f52c1b..ea21511a20 100644
--- a/src/backend/bootstrap/bootparse.y
+++ b/src/backend/bootstrap/bootparse.y
@@ -303,6 +303,7 @@ Boot_DeclareIndexStmt:
 					stmt->concurrent = false;
 					stmt->if_not_exists = false;
 					stmt->reset_default_tblspc = false;
+					stmt->isvisible = true;
 
 					/* locks and races need not concern us in bootstrap mode */
 					relationId = RangeVarGetRelid(stmt->relation, NoLock,
@@ -356,6 +357,7 @@ Boot_DeclareUniqueIndexStmt:
 					stmt->concurrent = false;
 					stmt->if_not_exists = false;
 					stmt->reset_default_tblspc = false;
+					stmt->isvisible = true;
 
 					/* locks and races need not concern us in bootstrap mode */
 					relationId = RangeVarGetRelid(stmt->relation, NoLock,
diff --git a/src/backend/catalog/index.c b/src/backend/catalog/index.c
index 7377912b41..ef51e6de0b 100644
--- a/src/backend/catalog/index.c
+++ b/src/backend/catalog/index.c
@@ -118,7 +118,8 @@ static void UpdateIndexRelation(Oid indexoid, Oid heapoid,
 								bool isexclusion,
 								bool immediate,
 								bool isvalid,
-								bool isready);
+								bool isready,
+								bool isvisible);
 static void index_update_stats(Relation rel,
 							   bool hasindex,
 							   double reltuples);
@@ -570,7 +571,8 @@ UpdateIndexRelation(Oid indexoid,
 					bool isexclusion,
 					bool immediate,
 					bool isvalid,
-					bool isready)
+					bool isready,
+					bool isvisible)
 {
 	int2vector *indkey;
 	oidvector  *indcollation;
@@ -648,6 +650,7 @@ UpdateIndexRelation(Oid indexoid,
 	values[Anum_pg_index_indisready - 1] = BoolGetDatum(isready);
 	values[Anum_pg_index_indislive - 1] = BoolGetDatum(true);
 	values[Anum_pg_index_indisreplident - 1] = BoolGetDatum(false);
+	values[Anum_pg_index_indisvisible - 1] = BoolGetDatum(isvisible);
 	values[Anum_pg_index_indkey - 1] = PointerGetDatum(indkey);
 	values[Anum_pg_index_indcollation - 1] = PointerGetDatum(indcollation);
 	values[Anum_pg_index_indclass - 1] = PointerGetDatum(indclass);
@@ -713,6 +716,8 @@ UpdateIndexRelation(Oid indexoid,
  *			already exists.
  *		INDEX_CREATE_PARTITIONED:
  *			create a partitioned index (table must be partitioned)
+ *		INDEX_CREATE_VISIBLE:
+ *			create the index as visible to query planner
  * constr_flags: flags passed to index_constraint_create
  *		(only if INDEX_CREATE_ADD_CONSTRAINT is set)
  * allow_system_table_mods: allow table to be a system catalog
@@ -758,6 +763,7 @@ index_create(Relation heapRelation,
 	bool		invalid = (flags & INDEX_CREATE_INVALID) != 0;
 	bool		concurrent = (flags & INDEX_CREATE_CONCURRENT) != 0;
 	bool		partitioned = (flags & INDEX_CREATE_PARTITIONED) != 0;
+	bool 		isvisible  = (flags & INDEX_CREATE_VISIBLE) != 0;
 	char		relkind;
 	TransactionId relfrozenxid;
 	MultiXactId relminmxid;
@@ -1041,13 +1047,15 @@ index_create(Relation heapRelation,
 	 *	  (Or, could define a rule to maintain the predicate) --Nels, Feb '92
 	 * ----------------
 	 */
+
 	UpdateIndexRelation(indexRelationId, heapRelationId, parentIndexRelid,
 						indexInfo,
 						collationIds, opclassIds, coloptions,
 						isprimary, is_exclusion,
 						(constr_flags & INDEX_CONSTR_CREATE_DEFERRABLE) == 0,
 						!concurrent && !invalid,
-						!concurrent);
+						!concurrent,
+						isvisible);
 
 	/*
 	 * Register relcache invalidation on the indexes' heap relation, to
@@ -1316,6 +1324,8 @@ index_concurrently_create_copy(Relation heapRelation, Oid oldIndexId,
 	List	   *indexColNames = NIL;
 	List	   *indexExprs = NIL;
 	List	   *indexPreds = NIL;
+	Form_pg_index indexForm;
+	bits16 	 createFlags;
 
 	indexRelation = index_open(oldIndexId, RowExclusiveLock);
 
@@ -1343,6 +1353,9 @@ index_concurrently_create_copy(Relation heapRelation, Oid oldIndexId,
 											Anum_pg_index_indoption);
 	indcoloptions = (int2vector *) DatumGetPointer(colOptionDatum);
 
+	/* Get the visibility state of the original index */
+	indexForm = (Form_pg_index) GETSTRUCT(indexTuple);
+
 	/* Fetch reloptions of index if any */
 	classTuple = SearchSysCache1(RELOID, ObjectIdGetDatum(oldIndexId));
 	if (!HeapTupleIsValid(classTuple))
@@ -1434,6 +1447,16 @@ index_concurrently_create_copy(Relation heapRelation, Oid oldIndexId,
 		stattargets[i].isnull = isnull;
 	}
 
+	/*
+	* Determine the create flags for the new index.
+	* We always use SKIP_BUILD and CONCURRENT for concurrent reindexing.
+	* If the original index was visible, we also set the VISIBLE flag
+	* to maintain the same state in the new index.
+	*/
+	createFlags = INDEX_CREATE_SKIP_BUILD | INDEX_CREATE_CONCURRENT;
+	if (indexForm->indisvisible)
+			createFlags |= INDEX_CREATE_VISIBLE;
+
 	/*
 	 * Now create the new index.
 	 *
@@ -1457,7 +1480,7 @@ index_concurrently_create_copy(Relation heapRelation, Oid oldIndexId,
 							  indcoloptions->values,
 							  stattargets,
 							  reloptionsDatum,
-							  INDEX_CREATE_SKIP_BUILD | INDEX_CREATE_CONCURRENT,
+							  createFlags,
 							  0,
 							  true, /* allow table to be a system catalog? */
 							  false,	/* is_internal? */
diff --git a/src/backend/catalog/toasting.c b/src/backend/catalog/toasting.c
index 874a8fc89a..7721d16fd3 100644
--- a/src/backend/catalog/toasting.c
+++ b/src/backend/catalog/toasting.c
@@ -325,7 +325,7 @@ create_toast_table(Relation rel, Oid toastOid, Oid toastIndexOid,
 				 BTREE_AM_OID,
 				 rel->rd_rel->reltablespace,
 				 collationIds, opclassIds, NULL, coloptions, NULL, (Datum) 0,
-				 INDEX_CREATE_IS_PRIMARY, 0, true, true, NULL);
+				 INDEX_CREATE_IS_PRIMARY | INDEX_CREATE_VISIBLE, 0, true, true, NULL);
 
 	table_close(toast_rel, NoLock);
 
diff --git a/src/backend/commands/indexcmds.c b/src/backend/commands/indexcmds.c
index d6e23caef1..65cab9ba61 100644
--- a/src/backend/commands/indexcmds.c
+++ b/src/backend/commands/indexcmds.c
@@ -1198,6 +1198,10 @@ DefineIndex(Oid tableId,
 		flags |= INDEX_CREATE_PARTITIONED;
 	if (stmt->primary)
 		flags |= INDEX_CREATE_IS_PRIMARY;
+   if (stmt->isvisible)
+		flags |= INDEX_CREATE_VISIBLE;
+   else
+		flags &= ~INDEX_CREATE_VISIBLE;
 
 	/*
 	 * If the table is partitioned, and recursion was declined but partitions
diff --git a/src/backend/commands/tablecmds.c b/src/backend/commands/tablecmds.c
index 4fc54bd6eb..f83b8e2fbc 100644
--- a/src/backend/commands/tablecmds.c
+++ b/src/backend/commands/tablecmds.c
@@ -688,7 +688,7 @@ static List *GetParentedForeignKeyRefs(Relation partition);
 static void ATDetachCheckNoForeignKeyRefs(Relation partition);
 static char GetAttributeCompression(Oid atttypid, const char *compression);
 static char GetAttributeStorage(Oid atttypid, const char *storagemode);
-
+static void ATExecSetIndexVisibility(Relation rel, bool visible);
 
 /* ----------------------------------------------------------------
  *		DefineRelation
@@ -4648,6 +4648,8 @@ AlterTableGetLockLevel(List *cmds)
 			case AT_SetExpression:
 			case AT_DropExpression:
 			case AT_SetCompression:
+			case AT_SetIndexVisible:
+			case AT_SetIndexInvisible:
 				cmd_lockmode = AccessExclusiveLock;
 				break;
 
@@ -5210,6 +5212,12 @@ ATPrepCmd(List **wqueue, Relation rel, AlterTableCmd *cmd,
 			/* No command-specific prep needed */
 			pass = AT_PASS_MISC;
 			break;
+		case AT_SetIndexVisible:
+		case AT_SetIndexInvisible:
+			ATSimplePermissions(cmd->subtype, rel, ATT_INDEX | ATT_PARTITIONED_INDEX);
+			/* No command-specific prep needed */
+			pass = AT_PASS_MISC;
+			break;
 		default:				/* oops */
 			elog(ERROR, "unrecognized alter table type: %d",
 				 (int) cmd->subtype);
@@ -5604,6 +5612,12 @@ ATExecCmd(List **wqueue, AlteredTableInfo *tab,
 		case AT_DetachPartitionFinalize:
 			address = ATExecDetachPartitionFinalize(rel, ((PartitionCmd *) cmd->def)->name);
 			break;
+		case AT_SetIndexVisible:
+				ATExecSetIndexVisibility(rel, true);
+				break;
+		case AT_SetIndexInvisible:
+				ATExecSetIndexVisibility(rel, false);
+				break;
 		default:				/* oops */
 			elog(ERROR, "unrecognized alter table type: %d",
 				 (int) cmd->subtype);
@@ -6498,6 +6512,8 @@ alter_table_type_to_string(AlterTableType cmdtype)
 			return "DROP COLUMN";
 		case AT_AddIndex:
 		case AT_ReAddIndex:
+		case AT_SetIndexVisible:
+		case AT_SetIndexInvisible:
 			return NULL;		/* not real grammar */
 		case AT_AddConstraint:
 		case AT_ReAddConstraint:
@@ -20861,3 +20877,57 @@ GetAttributeStorage(Oid atttypid, const char *storagemode)
 
 	return cstorage;
 }
+
+/*
+ * ATExecSetIndexVisibility
+ * Performs a catalog update to mark an index as visible or invisible in pg_index.
+ */
+static void
+ATExecSetIndexVisibility(Relation rel, bool visible)
+{
+	Oid         indexOid = RelationGetRelid(rel);
+	Oid         heapOid;
+	Relation    pg_index;
+	HeapTuple   indexTuple;
+	Form_pg_index indexForm;
+	bool        updated = false;
+	Relation    heapRel;
+
+	pg_index = table_open(IndexRelationId, RowExclusiveLock);
+
+	indexTuple = SearchSysCacheCopy1(INDEXRELID, ObjectIdGetDatum(indexOid));
+	if (!HeapTupleIsValid(indexTuple))
+		elog(ERROR, "could not find tuple for index %u", indexOid);
+
+	indexForm = (Form_pg_index) GETSTRUCT(indexTuple);
+	if (indexForm->indcheckxmin)
+	{
+		heap_freetuple(indexTuple);
+		table_close(pg_index, RowExclusiveLock);
+		ereport(ERROR,
+				(errcode(ERRCODE_OBJECT_NOT_IN_PREREQUISITE_STATE),
+				errmsg("cannot update index visibility while indcheckxmin is true"),
+				errhint("Wait for all transactions that might see inconsistent HOT chains to complete")));
+	}
+
+	if (indexForm->indisvisible != visible)
+	{
+		indexForm->indisvisible = visible;
+
+		CatalogTupleUpdate(pg_index, &indexTuple->t_self, indexTuple);
+		updated = true;
+	}
+
+	heap_freetuple(indexTuple);
+	table_close(pg_index, RowExclusiveLock);
+
+	if (updated)
+	{
+		heapOid = IndexGetRelation(indexOid, false);
+		heapRel = table_open(heapOid, AccessShareLock);
+		CacheInvalidateRelcache(heapRel);
+		table_close(heapRel, AccessShareLock);
+		InvokeObjectPostAlterHook(IndexRelationId, indexOid, 0);
+		CommandCounterIncrement();
+	}
+}
diff --git a/src/backend/optimizer/util/plancat.c b/src/backend/optimizer/util/plancat.c
index f2d319101d..5043751103 100644
--- a/src/backend/optimizer/util/plancat.c
+++ b/src/backend/optimizer/util/plancat.c
@@ -47,7 +47,9 @@
 #include "storage/bufmgr.h"
 #include "tcop/tcopprot.h"
 #include "utils/builtins.h"
+#include "utils/guc_hooks.h"
 #include "utils/lsyscache.h"
+#include "utils/plancache.h"
 #include "utils/partcache.h"
 #include "utils/rel.h"
 #include "utils/snapmgr.h"
@@ -55,6 +57,7 @@
 
 /* GUC parameter */
 int			constraint_exclusion = CONSTRAINT_EXCLUSION_PARTITION;
+bool		use_invisible_index = false;
 
 /* Hook for plugins to get control in get_relation_info() */
 get_relation_info_hook_type get_relation_info_hook = NULL;
@@ -254,13 +257,12 @@ get_relation_info(PlannerInfo *root, Oid relationObjectId, bool inhparent,
 			index = indexRelation->rd_index;
 
 			/*
-			 * Ignore invalid indexes, since they can't safely be used for
-			 * queries.  Note that this is OK because the data structure we
-			 * are constructing is only used by the planner --- the executor
-			 * still needs to insert into "invalid" indexes, if they're marked
-			 * indisready.
-			 */
-			if (!index->indisvalid)
+			 * Skip invalid indexes, and invisible indexes unless use_invisible_index
+			 * is set. This is OK because the data structure we are constructing is
+			 * only used by the planner - the executor still needs to insert into
+			 * these indexes if they're marked indisready.
+			*/
+			if (!index->indisvalid || (!index->indisvisible && !use_invisible_index))
 			{
 				index_close(indexRelation, NoLock);
 				continue;
@@ -2610,3 +2612,18 @@ set_baserel_partition_constraint(Relation relation, RelOptInfo *rel)
 		rel->partition_qual = partconstr;
 	}
 }
+
+/*
+ * assign_use_invisible_index
+ * GUC assign_hook for "use_invisible_index" GUC variable.
+ * Resets the plan cache when the value changes.
+ */
+void
+assign_use_invisible_index(bool newval, void *extra)
+{
+	if (use_invisible_index != newval)
+	{
+		use_invisible_index = newval;
+		ResetPlanCache();
+	}
+}
diff --git a/src/backend/parser/gram.y b/src/backend/parser/gram.y
index 6079de70e0..1b6f93cffc 100644
--- a/src/backend/parser/gram.y
+++ b/src/backend/parser/gram.y
@@ -322,7 +322,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 %type <ival>	add_drop opt_asc_desc opt_nulls_order
 
 %type <node>	alter_table_cmd alter_type_cmd opt_collate_clause
-	   replica_identity partition_cmd index_partition_cmd
+	   replica_identity partition_cmd index_partition_cmd index_alter_cmd
 %type <list>	alter_table_cmds alter_type_cmds
 %type <list>    alter_identity_column_option_list
 %type <defelt>  alter_identity_column_option
@@ -485,6 +485,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 %type <boolean> opt_unique opt_verbose opt_full
 %type <boolean> opt_freeze opt_analyze opt_default
 %type <defelt>	opt_binary copy_delimiter
+%type <boolean>  opt_index_visibility
 
 %type <boolean> copy_from opt_program
 
@@ -727,7 +728,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 	IDENTITY_P IF_P ILIKE IMMEDIATE IMMUTABLE IMPLICIT_P IMPORT_P IN_P INCLUDE
 	INCLUDING INCREMENT INDENT INDEX INDEXES INHERIT INHERITS INITIALLY INLINE_P
 	INNER_P INOUT INPUT_P INSENSITIVE INSERT INSTEAD INT_P INTEGER
-	INTERSECT INTERVAL INTO INVOKER IS ISNULL ISOLATION
+	INTERSECT INTERVAL INTO INVISIBLE_P INVOKER IS ISNULL ISOLATION
 
 	JOIN JSON JSON_ARRAY JSON_ARRAYAGG JSON_EXISTS JSON_OBJECT JSON_OBJECTAGG
 	JSON_QUERY JSON_SCALAR JSON_SERIALIZE JSON_TABLE JSON_VALUE
@@ -778,7 +779,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 	UNLISTEN UNLOGGED UNTIL UPDATE USER USING
 
 	VACUUM VALID VALIDATE VALIDATOR VALUE_P VALUES VARCHAR VARIADIC VARYING
-	VERBOSE VERSION_P VIEW VIEWS VOLATILE
+	VERBOSE VERSION_P VIEW VIEWS VISIBLE_P VOLATILE
 
 	WHEN WHERE WHITESPACE_P WINDOW WITH WITHIN WITHOUT WORK WRAPPER WRITE
 
@@ -2151,6 +2152,24 @@ AlterTableStmt:
 					n->nowait = $13;
 					$$ = (Node *) n;
 				}
+		| ALTER INDEX qualified_name index_alter_cmd
+				{
+					AlterTableStmt *n = makeNode(AlterTableStmt);
+					n->relation = $3;
+					n->cmds = list_make1($4);
+					n->objtype = OBJECT_INDEX;
+					n->missing_ok = false;
+					$$ = (Node *) n;
+				}
+		| ALTER INDEX IF_P EXISTS qualified_name index_alter_cmd
+				{
+					AlterTableStmt *n = makeNode(AlterTableStmt);
+					n->relation = $5;
+					n->cmds = list_make1($6);
+					n->objtype = OBJECT_INDEX;
+					n->missing_ok = true;
+					$$ = (Node *) n;
+				}
 		|	ALTER INDEX qualified_name alter_table_cmds
 				{
 					AlterTableStmt *n = makeNode(AlterTableStmt);
@@ -2376,6 +2395,21 @@ index_partition_cmd:
 				}
 		;
 
+index_alter_cmd:
+		/* ALTER INDEX <name> VISIBLE|INVISIBLE */
+		VISIBLE_P
+			{
+				AlterTableCmd *n = makeNode(AlterTableCmd);
+				n->subtype = AT_SetIndexVisible;
+				$$ = (Node *) n;
+			}
+		| INVISIBLE_P
+			{
+				AlterTableCmd *n = makeNode(AlterTableCmd);
+				n->subtype = AT_SetIndexInvisible;
+				$$ = (Node *) n;
+			}
+		;
 alter_table_cmd:
 			/* ALTER TABLE <name> ADD <coldef> */
 			ADD_P columnDef
@@ -8154,7 +8188,7 @@ defacl_privilege_target:
 
 IndexStmt:	CREATE opt_unique INDEX opt_concurrently opt_single_name
 			ON relation_expr access_method_clause '(' index_params ')'
-			opt_include opt_unique_null_treatment opt_reloptions OptTableSpace where_clause
+			opt_include opt_unique_null_treatment opt_reloptions OptTableSpace where_clause opt_index_visibility
 				{
 					IndexStmt *n = makeNode(IndexStmt);
 
@@ -8169,6 +8203,7 @@ IndexStmt:	CREATE opt_unique INDEX opt_concurrently opt_single_name
 					n->options = $14;
 					n->tableSpace = $15;
 					n->whereClause = $16;
+					n->isvisible = $17;
 					n->excludeOpNames = NIL;
 					n->idxcomment = NULL;
 					n->indexOid = InvalidOid;
@@ -8186,7 +8221,7 @@ IndexStmt:	CREATE opt_unique INDEX opt_concurrently opt_single_name
 				}
 			| CREATE opt_unique INDEX opt_concurrently IF_P NOT EXISTS name
 			ON relation_expr access_method_clause '(' index_params ')'
-			opt_include opt_unique_null_treatment opt_reloptions OptTableSpace where_clause
+			opt_include opt_unique_null_treatment opt_reloptions OptTableSpace where_clause opt_index_visibility
 				{
 					IndexStmt *n = makeNode(IndexStmt);
 
@@ -8201,6 +8236,7 @@ IndexStmt:	CREATE opt_unique INDEX opt_concurrently opt_single_name
 					n->options = $17;
 					n->tableSpace = $18;
 					n->whereClause = $19;
+					n->isvisible = $20;
 					n->excludeOpNames = NIL;
 					n->idxcomment = NULL;
 					n->indexOid = InvalidOid;
@@ -8223,6 +8259,12 @@ opt_unique:
 			| /*EMPTY*/								{ $$ = false; }
 		;
 
+opt_index_visibility:
+			VISIBLE_P                      { $$ = true; }
+			| INVISIBLE_P                   { $$ = false; }
+			| /*EMPTY*/                 	{ $$ = true; }
+		;
+
 access_method_clause:
 			USING name								{ $$ = $2; }
 			| /*EMPTY*/								{ $$ = DEFAULT_INDEX_TYPE; }
@@ -17763,6 +17805,7 @@ unreserved_keyword:
 			| INSENSITIVE
 			| INSERT
 			| INSTEAD
+			| INVISIBLE_P
 			| INVOKER
 			| ISOLATION
 			| KEEP
@@ -17947,6 +17990,7 @@ unreserved_keyword:
 			| VERSION_P
 			| VIEW
 			| VIEWS
+			|	VISIBLE_P
 			| VOLATILE
 			| WHITESPACE_P
 			| WITHIN
@@ -18356,6 +18400,7 @@ bare_label_keyword:
 			| INT_P
 			| INTEGER
 			| INTERVAL
+			| INVISIBLE_P
 			| INVOKER
 			| IS
 			| ISOLATION
@@ -18602,6 +18647,7 @@ bare_label_keyword:
 			| VERSION_P
 			| VIEW
 			| VIEWS
+			| VISIBLE_P
 			| VOLATILE
 			| WHEN
 			| WHITESPACE_P
diff --git a/src/backend/parser/parse_utilcmd.c b/src/backend/parser/parse_utilcmd.c
index ca028d2a66..9cd8a65b52 100644
--- a/src/backend/parser/parse_utilcmd.c
+++ b/src/backend/parser/parse_utilcmd.c
@@ -1743,6 +1743,7 @@ generateClonedIndexStmt(RangeVar *heapRel, Relation source_idx,
 	index->concurrent = false;
 	index->if_not_exists = false;
 	index->reset_default_tblspc = false;
+	index->isvisible = idxrec->indisvisible;
 
 	/*
 	 * We don't try to preserve the name of the source index; instead, just
@@ -2364,6 +2365,8 @@ transformIndexConstraint(Constraint *constraint, CreateStmtContext *cxt)
 	index->concurrent = false;
 	index->if_not_exists = false;
 	index->reset_default_tblspc = constraint->reset_default_tblspc;
+	/* Ensure indexes for constraints are created as visible by default */
+	index->isvisible = true;
 
 	/*
 	 * If it's ALTER TABLE ADD CONSTRAINT USING INDEX, look up the index and
diff --git a/src/backend/utils/adt/ruleutils.c b/src/backend/utils/adt/ruleutils.c
index 2a77f715fb..38dfb98978 100644
--- a/src/backend/utils/adt/ruleutils.c
+++ b/src/backend/utils/adt/ruleutils.c
@@ -1559,6 +1559,10 @@ pg_get_indexdef_worker(Oid indexrelid, int colno,
 			else
 				appendStringInfo(&buf, " WHERE %s", str);
 		}
+
+		/* Add INVISIBLE clause if the index is invisible */
+		if (!idxrec->indisvisible)
+				appendStringInfoString(&buf, " INVISIBLE");
 	}
 
 	/* Clean up */
diff --git a/src/backend/utils/cache/relcache.c b/src/backend/utils/cache/relcache.c
index 43219a9629..8c084622eb 100644
--- a/src/backend/utils/cache/relcache.c
+++ b/src/backend/utils/cache/relcache.c
@@ -2311,6 +2311,7 @@ RelationReloadIndexInfo(Relation relation)
 		relation->rd_index->indisready = index->indisready;
 		relation->rd_index->indislive = index->indislive;
 		relation->rd_index->indisreplident = index->indisreplident;
+		relation->rd_index->indisvisible = index->indisvisible;
 
 		/* Copy xmin too, as that is needed to make sense of indcheckxmin */
 		HeapTupleHeaderSetXmin(relation->rd_indextuple->t_data,
diff --git a/src/backend/utils/misc/guc_tables.c b/src/backend/utils/misc/guc_tables.c
index c9d8cd796a..df370d4e87 100644
--- a/src/backend/utils/misc/guc_tables.c
+++ b/src/backend/utils/misc/guc_tables.c
@@ -2095,6 +2095,17 @@ struct config_bool ConfigureNamesBool[] =
 		NULL, NULL, NULL
 	},
 
+	{
+		{"use_invisible_index", PGC_USERSET, QUERY_TUNING_OTHER,
+			gettext_noop("Forces the planner to consider invisible indexes."),
+			NULL,
+			GUC_NOT_IN_SAMPLE | GUC_EXPLAIN
+		},
+		&use_invisible_index,
+		false,
+		NULL, assign_use_invisible_index, NULL
+	},
+
 	/* End-of-list marker */
 	{
 		{NULL, 0, 0, NULL, NULL}, NULL, false, NULL, NULL, NULL
diff --git a/src/include/catalog/index.h b/src/include/catalog/index.h
index 4daa8bef5e..ff0f9916de 100644
--- a/src/include/catalog/index.h
+++ b/src/include/catalog/index.h
@@ -65,6 +65,7 @@ extern void index_check_primary_key(Relation heapRel,
 #define	INDEX_CREATE_IF_NOT_EXISTS			(1 << 4)
 #define	INDEX_CREATE_PARTITIONED			(1 << 5)
 #define INDEX_CREATE_INVALID				(1 << 6)
+#define INDEX_CREATE_VISIBLE        (1 << 7)
 
 extern Oid	index_create(Relation heapRelation,
 						 const char *indexRelationName,
@@ -175,7 +176,6 @@ extern void RestoreReindexState(const void *reindexstate);
 
 extern void IndexSetParentIndex(Relation partitionIdx, Oid parentOid);
 
-
 /*
  * itemptr_encode - Encode ItemPointer as int64/int8
  *
diff --git a/src/include/catalog/pg_index.h b/src/include/catalog/pg_index.h
index 9eb99d31fa..c3b996d752 100644
--- a/src/include/catalog/pg_index.h
+++ b/src/include/catalog/pg_index.h
@@ -44,6 +44,7 @@ CATALOG(pg_index,2610,IndexRelationId) BKI_SCHEMA_MACRO
 	bool		indisready;		/* is this index ready for inserts? */
 	bool		indislive;		/* is this index alive at all? */
 	bool		indisreplident; /* is this index the identity for replication? */
+	bool		indisvisible BKI_DEFAULT(t);	/* is this index visible for use by queries? */
 
 	/* variable-length fields start here, but we allow direct access to indkey */
 	int2vector	indkey BKI_FORCE_NOT_NULL;	/* column numbers of indexed cols,
diff --git a/src/include/nodes/parsenodes.h b/src/include/nodes/parsenodes.h
index b191eaaeca..bb980528c4 100644
--- a/src/include/nodes/parsenodes.h
+++ b/src/include/nodes/parsenodes.h
@@ -2423,6 +2423,8 @@ typedef enum AlterTableType
 	AT_SetIdentity,				/* SET identity column options */
 	AT_DropIdentity,			/* DROP IDENTITY */
 	AT_ReAddStatistics,			/* internal to commands/tablecmds.c */
+	AT_SetIndexVisible,					/* Set INDEX visible */
+	AT_SetIndexInvisible,				/* Set INDEX invisible */
 } AlterTableType;
 
 typedef struct ReplicaIdentityStmt
@@ -3405,6 +3407,7 @@ typedef struct IndexStmt
 	bool		if_not_exists;	/* just do nothing if index already exists? */
 	bool		reset_default_tblspc;	/* reset default_tablespace prior to
 										 * executing */
+  bool		isvisible;		/* true if VISIBLE (default), false if INVISIBLE */
 } IndexStmt;
 
 /* ----------------------
diff --git a/src/include/optimizer/optimizer.h b/src/include/optimizer/optimizer.h
index 734c82a27d..c96726fcff 100644
--- a/src/include/optimizer/optimizer.h
+++ b/src/include/optimizer/optimizer.h
@@ -204,4 +204,9 @@ extern List *pull_var_clause(Node *node, int flags);
 extern Node *flatten_join_alias_vars(PlannerInfo *root, Query *query, Node *node);
 extern Node *flatten_group_exprs(PlannerInfo *root, Query *query, Node *node);
 
+/*
+ * GUC to tell planner to consider invisible indexes.
+ */
+extern bool use_invisible_index;
+
 #endif							/* OPTIMIZER_H */
diff --git a/src/include/parser/kwlist.h b/src/include/parser/kwlist.h
index cf2917ad07..18b97aefb0 100644
--- a/src/include/parser/kwlist.h
+++ b/src/include/parser/kwlist.h
@@ -229,6 +229,7 @@ PG_KEYWORD("integer", INTEGER, COL_NAME_KEYWORD, BARE_LABEL)
 PG_KEYWORD("intersect", INTERSECT, RESERVED_KEYWORD, AS_LABEL)
 PG_KEYWORD("interval", INTERVAL, COL_NAME_KEYWORD, BARE_LABEL)
 PG_KEYWORD("into", INTO, RESERVED_KEYWORD, AS_LABEL)
+PG_KEYWORD("invisible", INVISIBLE_P, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("invoker", INVOKER, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("is", IS, TYPE_FUNC_NAME_KEYWORD, BARE_LABEL)
 PG_KEYWORD("isnull", ISNULL, TYPE_FUNC_NAME_KEYWORD, AS_LABEL)
@@ -491,6 +492,7 @@ PG_KEYWORD("verbose", VERBOSE, TYPE_FUNC_NAME_KEYWORD, BARE_LABEL)
 PG_KEYWORD("version", VERSION_P, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("view", VIEW, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("views", VIEWS, UNRESERVED_KEYWORD, BARE_LABEL)
+PG_KEYWORD("visible", VISIBLE_P, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("volatile", VOLATILE, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("when", WHEN, RESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("where", WHERE, RESERVED_KEYWORD, AS_LABEL)
diff --git a/src/include/utils/guc_hooks.h b/src/include/utils/guc_hooks.h
index 87999218d6..909f9b57ed 100644
--- a/src/include/utils/guc_hooks.h
+++ b/src/include/utils/guc_hooks.h
@@ -174,5 +174,6 @@ extern void assign_wal_sync_method(int new_wal_sync_method, void *extra);
 extern bool check_synchronized_standby_slots(char **newval, void **extra,
 											 GucSource source);
 extern void assign_synchronized_standby_slots(const char *newval, void *extra);
+extern void assign_use_invisible_index(bool newval, void *extra);
 
 #endif							/* GUC_HOOKS_H */
diff --git a/src/test/regress/expected/create_index.out b/src/test/regress/expected/create_index.out
index 8011c141bf..941a4f0235 100644
--- a/src/test/regress/expected/create_index.out
+++ b/src/test/regress/expected/create_index.out
@@ -3331,6 +3331,592 @@ ERROR:  REINDEX SCHEMA cannot run inside a transaction block
 END;
 -- concurrently
 REINDEX SCHEMA CONCURRENTLY schema_to_reindex;
+-- Test index visibility functionality
+CREATE TABLE index_test(
+    id INT PRIMARY KEY,
+    data TEXT,
+    num INT,
+    vector INT[],
+    range INT4RANGE
+);
+INSERT INTO index_test
+SELECT
+    g,
+    'data ' || g,
+    g % 100,
+    ARRAY[g, g+1, g+2],
+    int4range(g, g+10)
+FROM generate_series(1, 1000) g;
+-- Function for testing
+CREATE FUNCTION get_data_length(text) RETURNS INT AS $$
+    SELECT length($1);
+$$ LANGUAGE SQL IMMUTABLE;
+-- Helper function to show index status
+CREATE OR REPLACE FUNCTION show_index_status(index_name text)
+RETURNS TABLE (
+    indexrelid regclass,
+    indisvalid boolean,
+    indisready boolean,
+    indislive boolean,
+    indisvisible boolean
+) AS $$
+BEGIN
+    RETURN QUERY EXECUTE format('
+        SELECT indexrelid::regclass, indisvalid, indisready, indislive, indisvisible
+        FROM pg_index
+        WHERE indexrelid = %L::regclass', index_name);
+END;
+$$ LANGUAGE plpgsql;
+-- Create and test each index type
+-- 1. Basic single-column index
+CREATE INDEX idx_single ON index_test(data);
+SELECT show_index_status('idx_single');
+  show_index_status   
+----------------------
+ (idx_single,t,t,t,t)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE data = 'data 500';
+                  QUERY PLAN                   
+-----------------------------------------------
+ Bitmap Heap Scan on index_test
+   Recheck Cond: (data = 'data 500'::text)
+   ->  Bitmap Index Scan on idx_single
+         Index Cond: (data = 'data 500'::text)
+(4 rows)
+
+ALTER INDEX idx_single INVISIBLE;
+SELECT show_index_status('idx_single');
+  show_index_status   
+----------------------
+ (idx_single,t,t,t,f)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE data = 'data 500';
+             QUERY PLAN              
+-------------------------------------
+ Seq Scan on index_test
+   Filter: (data = 'data 500'::text)
+(2 rows)
+
+ALTER INDEX idx_single VISIBLE;
+SELECT show_index_status('idx_single');
+  show_index_status   
+----------------------
+ (idx_single,t,t,t,t)
+(1 row)
+
+-- 2. Multi-column index
+CREATE INDEX idx_multi ON index_test(num, data);
+SELECT show_index_status('idx_multi');
+  show_index_status  
+---------------------
+ (idx_multi,t,t,t,t)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE num = 50 AND data > 'data 500';
+                           QUERY PLAN                           
+----------------------------------------------------------------
+ Bitmap Heap Scan on index_test
+   Recheck Cond: ((num = 50) AND (data > 'data 500'::text))
+   ->  Bitmap Index Scan on idx_multi
+         Index Cond: ((num = 50) AND (data > 'data 500'::text))
+(4 rows)
+
+ALTER INDEX idx_multi INVISIBLE;
+SELECT show_index_status('idx_multi');
+  show_index_status  
+---------------------
+ (idx_multi,t,t,t,f)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE num = 50 AND data > 'data 500';
+                      QUERY PLAN                      
+------------------------------------------------------
+ Seq Scan on index_test
+   Filter: ((data > 'data 500'::text) AND (num = 50))
+(2 rows)
+
+ALTER INDEX idx_multi VISIBLE;
+SELECT show_index_status('idx_multi');
+  show_index_status  
+---------------------
+ (idx_multi,t,t,t,t)
+(1 row)
+
+-- 3. Partial index
+CREATE INDEX idx_partial ON index_test(num) WHERE num < 50;
+SELECT show_index_status('idx_partial');
+   show_index_status   
+-----------------------
+ (idx_partial,t,t,t,t)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE num = 25;
+               QUERY PLAN               
+----------------------------------------
+ Bitmap Heap Scan on index_test
+   Recheck Cond: (num = 25)
+   ->  Bitmap Index Scan on idx_partial
+         Index Cond: (num = 25)
+(4 rows)
+
+ALTER INDEX idx_partial INVISIBLE;
+SELECT show_index_status('idx_partial');
+   show_index_status   
+-----------------------
+ (idx_partial,t,t,t,f)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE num = 25;
+              QUERY PLAN              
+--------------------------------------
+ Bitmap Heap Scan on index_test
+   Recheck Cond: (num = 25)
+   ->  Bitmap Index Scan on idx_multi
+         Index Cond: (num = 25)
+(4 rows)
+
+ALTER INDEX idx_partial VISIBLE;
+SELECT show_index_status('idx_partial');
+   show_index_status   
+-----------------------
+ (idx_partial,t,t,t,t)
+(1 row)
+
+-- 4. Expression index
+CREATE INDEX idx_expression ON index_test((lower(data)));
+SELECT show_index_status('idx_expression');
+    show_index_status     
+--------------------------
+ (idx_expression,t,t,t,t)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE lower(data) = 'data 500';
+                      QUERY PLAN                      
+------------------------------------------------------
+ Bitmap Heap Scan on index_test
+   Recheck Cond: (lower(data) = 'data 500'::text)
+   ->  Bitmap Index Scan on idx_expression
+         Index Cond: (lower(data) = 'data 500'::text)
+(4 rows)
+
+ALTER INDEX idx_expression INVISIBLE;
+SELECT show_index_status('idx_expression');
+    show_index_status     
+--------------------------
+ (idx_expression,t,t,t,f)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE lower(data) = 'data 500';
+                 QUERY PLAN                 
+--------------------------------------------
+ Seq Scan on index_test
+   Filter: (lower(data) = 'data 500'::text)
+(2 rows)
+
+ALTER INDEX idx_expression VISIBLE;
+SELECT show_index_status('idx_expression');
+    show_index_status     
+--------------------------
+ (idx_expression,t,t,t,t)
+(1 row)
+
+-- 5. GIN index
+CREATE INDEX idx_gin ON index_test USING gin(vector);
+SELECT show_index_status('idx_gin');
+ show_index_status 
+-------------------
+ (idx_gin,t,t,t,t)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE vector @> ARRAY[500];
+                     QUERY PLAN                     
+----------------------------------------------------
+ Bitmap Heap Scan on index_test
+   Recheck Cond: (vector @> '{500}'::integer[])
+   ->  Bitmap Index Scan on idx_gin
+         Index Cond: (vector @> '{500}'::integer[])
+(4 rows)
+
+ALTER INDEX idx_gin INVISIBLE;
+SELECT show_index_status('idx_gin');
+ show_index_status 
+-------------------
+ (idx_gin,t,t,t,f)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE vector @> ARRAY[500];
+                QUERY PLAN                
+------------------------------------------
+ Seq Scan on index_test
+   Filter: (vector @> '{500}'::integer[])
+(2 rows)
+
+ALTER INDEX idx_gin VISIBLE;
+SELECT show_index_status('idx_gin');
+ show_index_status 
+-------------------
+ (idx_gin,t,t,t,t)
+(1 row)
+
+-- 6. GiST index
+CREATE INDEX idx_gist ON index_test USING gist(range);
+SELECT show_index_status('idx_gist');
+ show_index_status  
+--------------------
+ (idx_gist,t,t,t,t)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE range && int4range(100, 110);
+                      QUERY PLAN                       
+-------------------------------------------------------
+ Bitmap Heap Scan on index_test
+   Recheck Cond: (range && '[100,110)'::int4range)
+   ->  Bitmap Index Scan on idx_gist
+         Index Cond: (range && '[100,110)'::int4range)
+(4 rows)
+
+ALTER INDEX idx_gist INVISIBLE;
+SELECT show_index_status('idx_gist');
+ show_index_status  
+--------------------
+ (idx_gist,t,t,t,f)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE range && int4range(100, 110);
+                 QUERY PLAN                  
+---------------------------------------------
+ Seq Scan on index_test
+   Filter: (range && '[100,110)'::int4range)
+(2 rows)
+
+ALTER INDEX idx_gist VISIBLE;
+SELECT show_index_status('idx_gist');
+ show_index_status  
+--------------------
+ (idx_gist,t,t,t,t)
+(1 row)
+
+-- 7. Covering index
+CREATE INDEX idx_covering ON index_test(num) INCLUDE (data);
+SELECT show_index_status('idx_covering');
+   show_index_status    
+------------------------
+ (idx_covering,t,t,t,t)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT num, data FROM index_test WHERE num = 50;
+               QUERY PLAN                
+-----------------------------------------
+ Bitmap Heap Scan on index_test
+   Recheck Cond: (num = 50)
+   ->  Bitmap Index Scan on idx_covering
+         Index Cond: (num = 50)
+(4 rows)
+
+ALTER INDEX idx_covering INVISIBLE;
+SELECT show_index_status('idx_covering');
+   show_index_status    
+------------------------
+ (idx_covering,t,t,t,f)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT num, data FROM index_test WHERE num = 50;
+              QUERY PLAN              
+--------------------------------------
+ Bitmap Heap Scan on index_test
+   Recheck Cond: (num = 50)
+   ->  Bitmap Index Scan on idx_multi
+         Index Cond: (num = 50)
+(4 rows)
+
+ALTER INDEX idx_covering VISIBLE;
+SELECT show_index_status('idx_covering');
+   show_index_status    
+------------------------
+ (idx_covering,t,t,t,t)
+(1 row)
+
+-- 8. Unique index
+CREATE UNIQUE INDEX idx_unique ON index_test(id, data);
+SELECT show_index_status('idx_unique');
+  show_index_status   
+----------------------
+ (idx_unique,t,t,t,t)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE id = 500 AND data = 'data 500';
+                        QUERY PLAN                        
+----------------------------------------------------------
+ Index Scan using idx_unique on index_test
+   Index Cond: ((id = 500) AND (data = 'data 500'::text))
+(2 rows)
+
+ALTER INDEX idx_unique INVISIBLE;
+SELECT show_index_status('idx_unique');
+  show_index_status   
+----------------------
+ (idx_unique,t,t,t,f)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE id = 500 AND data = 'data 500';
+                   QUERY PLAN                   
+------------------------------------------------
+ Index Scan using index_test_pkey on index_test
+   Index Cond: (id = 500)
+   Filter: (data = 'data 500'::text)
+(3 rows)
+
+ALTER INDEX idx_unique VISIBLE;
+SELECT show_index_status('idx_unique');
+  show_index_status   
+----------------------
+ (idx_unique,t,t,t,t)
+(1 row)
+
+-- 9. Function-based index
+CREATE INDEX idx_func ON index_test(get_data_length(data));
+SELECT show_index_status('idx_func');
+ show_index_status  
+--------------------
+ (idx_func,t,t,t,t)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE get_data_length(data) = 10;
+               QUERY PLAN                
+-----------------------------------------
+ Bitmap Heap Scan on index_test
+   Recheck Cond: (length(data) = 10)
+   ->  Bitmap Index Scan on idx_func
+         Index Cond: (length(data) = 10)
+(4 rows)
+
+ALTER INDEX idx_func INVISIBLE;
+SELECT show_index_status('idx_func');
+ show_index_status  
+--------------------
+ (idx_func,t,t,t,f)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE get_data_length(data) = 10;
+          QUERY PLAN           
+-------------------------------
+ Seq Scan on index_test
+   Filter: (length(data) = 10)
+(2 rows)
+
+ALTER INDEX idx_func VISIBLE;
+SELECT show_index_status('idx_func');
+ show_index_status  
+--------------------
+ (idx_func,t,t,t,t)
+(1 row)
+
+-- 10. Join index
+CREATE TABLE join_test (id INT PRIMARY KEY, ref_id INT);
+INSERT INTO join_test SELECT g, g % 100 FROM generate_series(1, 1000) g;
+CREATE INDEX idx_join ON join_test(ref_id);
+SELECT show_index_status('idx_join');
+ show_index_status  
+--------------------
+ (idx_join,t,t,t,t)
+(1 row)
+
+EXPLAIN (COSTS OFF)
+SELECT jt.id, it.data
+FROM join_test jt
+JOIN index_test it ON jt.ref_id = it.num
+WHERE jt.id BETWEEN 100 AND 200;
+                          QUERY PLAN                           
+---------------------------------------------------------------
+ Hash Join
+   Hash Cond: (it.num = jt.ref_id)
+   ->  Seq Scan on index_test it
+   ->  Hash
+         ->  Bitmap Heap Scan on join_test jt
+               Recheck Cond: ((id >= 100) AND (id <= 200))
+               ->  Bitmap Index Scan on join_test_pkey
+                     Index Cond: ((id >= 100) AND (id <= 200))
+(8 rows)
+
+-- Set all indexes to invisible to force seq scan
+ALTER INDEX idx_join INVISIBLE;
+ALTER INDEX join_test_pkey INVISIBLE;
+SELECT show_index_status('idx_join');
+ show_index_status  
+--------------------
+ (idx_join,t,t,t,f)
+(1 row)
+
+SELECT show_index_status('join_test_pkey');
+    show_index_status     
+--------------------------
+ (join_test_pkey,t,t,t,f)
+(1 row)
+
+EXPLAIN (COSTS OFF)
+SELECT jt.id, it.data
+FROM join_test jt
+JOIN index_test it ON jt.ref_id = it.num
+WHERE jt.id BETWEEN 100 AND 200;
+                     QUERY PLAN                      
+-----------------------------------------------------
+ Hash Join
+   Hash Cond: (it.num = jt.ref_id)
+   ->  Seq Scan on index_test it
+   ->  Hash
+         ->  Seq Scan on join_test jt
+               Filter: ((id >= 100) AND (id <= 200))
+(6 rows)
+
+ALTER INDEX idx_join VISIBLE;
+ALTER INDEX join_test_pkey VISIBLE;
+SELECT show_index_status('idx_join');
+ show_index_status  
+--------------------
+ (idx_join,t,t,t,t)
+(1 row)
+
+SELECT show_index_status('join_test_pkey');
+    show_index_status     
+--------------------------
+ (join_test_pkey,t,t,t,t)
+(1 row)
+
+-- Test REINDEX CONCURRENTLY
+REINDEX INDEX CONCURRENTLY idx_join;
+SELECT show_index_status('idx_join');
+ show_index_status  
+--------------------
+ (idx_join,t,t,t,t)
+(1 row)
+
+ALTER INDEX idx_join INVISIBLE;
+SELECT show_index_status('idx_join');
+ show_index_status  
+--------------------
+ (idx_join,t,t,t,f)
+(1 row)
+
+REINDEX INDEX CONCURRENTLY idx_join;
+SELECT show_index_status('idx_join');
+ show_index_status  
+--------------------
+ (idx_join,t,t,t,f)
+(1 row)
+
+SELECT pg_get_indexdef('idx_join'::regclass);
+                                   pg_get_indexdef                                   
+-------------------------------------------------------------------------------------
+ CREATE INDEX idx_join ON schema_to_reindex.join_test USING btree (ref_id) INVISIBLE
+(1 row)
+
+ALTER INDEX idx_join VISIBLE;
+SELECT pg_get_indexdef('idx_join'::regclass);
+                              pg_get_indexdef                              
+---------------------------------------------------------------------------
+ CREATE INDEX idx_join ON schema_to_reindex.join_test USING btree (ref_id)
+(1 row)
+
+-- Test index visibility with indcheckxmin being true
+CREATE TABLE indcheckxmin_test(id int PRIMARY KEY);
+INSERT INTO indcheckxmin_test VALUES (1), (2), (3);
+CREATE INDEX CONCURRENTLY idx_checkxmin ON indcheckxmin_test(id);
+BEGIN;
+-- Simulate indcheckxmin being true
+UPDATE pg_index SET indcheckxmin = true WHERE indexrelid = 'idx_checkxmin'::regclass;
+ALTER INDEX idx_checkxmin INVISIBLE;  -- expect fail
+ERROR:  cannot update index visibility while indcheckxmin is true
+HINT:  Wait for all transactions that might see inconsistent HOT chains to complete
+ROLLBACK;
+-- Test prepared statements with index visibility
+CREATE TABLE prep_idx_test (id int, data text);
+CREATE INDEX prep_idx1 ON prep_idx_test(data);
+INSERT INTO prep_idx_test SELECT g, 'data ' || g FROM generate_series(1,100) g;
+-- Test with visible index
+PREPARE idx_plan AS SELECT * FROM prep_idx_test WHERE data = $1;
+EXPLAIN (COSTS OFF) EXECUTE idx_plan('data 1');
+                 QUERY PLAN                  
+---------------------------------------------
+ Bitmap Heap Scan on prep_idx_test
+   Recheck Cond: (data = 'data 1'::text)
+   ->  Bitmap Index Scan on prep_idx1
+         Index Cond: (data = 'data 1'::text)
+(4 rows)
+
+EXECUTE idx_plan('data 1');
+ id |  data  
+----+--------
+  1 | data 1
+(1 row)
+
+-- Test with invisible index
+ALTER INDEX prep_idx1 INVISIBLE;
+EXPLAIN (COSTS OFF) EXECUTE idx_plan('data 1');
+            QUERY PLAN             
+-----------------------------------
+ Seq Scan on prep_idx_test
+   Filter: (data = 'data 1'::text)
+(2 rows)
+
+EXECUTE idx_plan('data 1');
+ id |  data  
+----+--------
+  1 | data 1
+(1 row)
+
+-- Test with use_invisible_index
+SET use_invisible_index TO on;
+EXPLAIN (COSTS OFF) EXECUTE idx_plan('data 1');
+                 QUERY PLAN                  
+---------------------------------------------
+ Bitmap Heap Scan on prep_idx_test
+   Recheck Cond: (data = 'data 1'::text)
+   ->  Bitmap Index Scan on prep_idx1
+         Index Cond: (data = 'data 1'::text)
+(4 rows)
+
+EXECUTE idx_plan('data 1');
+ id |  data  
+----+--------
+  1 | data 1
+(1 row)
+
+SET use_invisible_index TO off;
+-- Assert plan cache is reset and index is not used
+EXPLAIN (COSTS OFF) EXECUTE idx_plan('data 1');
+            QUERY PLAN             
+-----------------------------------
+ Seq Scan on prep_idx_test
+   Filter: (data = 'data 1'::text)
+(2 rows)
+
+-- Make index visible and test again
+ALTER INDEX prep_idx1 VISIBLE;
+EXPLAIN (COSTS OFF) EXECUTE idx_plan('data 1');
+                 QUERY PLAN                  
+---------------------------------------------
+ Bitmap Heap Scan on prep_idx_test
+   Recheck Cond: (data = 'data 1'::text)
+   ->  Bitmap Index Scan on prep_idx1
+         Index Cond: (data = 'data 1'::text)
+(4 rows)
+
+EXECUTE idx_plan('data 1');
+ id |  data  
+----+--------
+  1 | data 1
+(1 row)
+
+-- Clean up
+DROP TABLE index_test;
+DROP TABLE join_test;
+DROP FUNCTION get_data_length;
+DROP FUNCTION show_index_status;
+DROP TABLE indcheckxmin_test CASCADE;
+DEALLOCATE idx_plan;
+DROP TABLE prep_idx_test;
 -- Failure for unauthorized user
 CREATE ROLE regress_reindexuser NOLOGIN;
 SET SESSION ROLE regress_reindexuser;
diff --git a/src/test/regress/sql/create_index.sql b/src/test/regress/sql/create_index.sql
index 068c66b95a..04f2eebda3 100644
--- a/src/test/regress/sql/create_index.sql
+++ b/src/test/regress/sql/create_index.sql
@@ -1415,6 +1415,228 @@ END;
 -- concurrently
 REINDEX SCHEMA CONCURRENTLY schema_to_reindex;
 
+-- Test index visibility functionality
+
+CREATE TABLE index_test(
+    id INT PRIMARY KEY,
+    data TEXT,
+    num INT,
+    vector INT[],
+    range INT4RANGE
+);
+
+INSERT INTO index_test
+SELECT
+    g,
+    'data ' || g,
+    g % 100,
+    ARRAY[g, g+1, g+2],
+    int4range(g, g+10)
+FROM generate_series(1, 1000) g;
+
+-- Function for testing
+CREATE FUNCTION get_data_length(text) RETURNS INT AS $$
+    SELECT length($1);
+$$ LANGUAGE SQL IMMUTABLE;
+
+-- Helper function to show index status
+CREATE OR REPLACE FUNCTION show_index_status(index_name text)
+RETURNS TABLE (
+    indexrelid regclass,
+    indisvalid boolean,
+    indisready boolean,
+    indislive boolean,
+    indisvisible boolean
+) AS $$
+BEGIN
+    RETURN QUERY EXECUTE format('
+        SELECT indexrelid::regclass, indisvalid, indisready, indislive, indisvisible
+        FROM pg_index
+        WHERE indexrelid = %L::regclass', index_name);
+END;
+$$ LANGUAGE plpgsql;
+
+-- Create and test each index type
+-- 1. Basic single-column index
+CREATE INDEX idx_single ON index_test(data);
+SELECT show_index_status('idx_single');
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE data = 'data 500';
+ALTER INDEX idx_single INVISIBLE;
+SELECT show_index_status('idx_single');
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE data = 'data 500';
+ALTER INDEX idx_single VISIBLE;
+SELECT show_index_status('idx_single');
+
+-- 2. Multi-column index
+CREATE INDEX idx_multi ON index_test(num, data);
+SELECT show_index_status('idx_multi');
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE num = 50 AND data > 'data 500';
+ALTER INDEX idx_multi INVISIBLE;
+SELECT show_index_status('idx_multi');
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE num = 50 AND data > 'data 500';
+ALTER INDEX idx_multi VISIBLE;
+SELECT show_index_status('idx_multi');
+
+-- 3. Partial index
+CREATE INDEX idx_partial ON index_test(num) WHERE num < 50;
+SELECT show_index_status('idx_partial');
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE num = 25;
+ALTER INDEX idx_partial INVISIBLE;
+SELECT show_index_status('idx_partial');
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE num = 25;
+ALTER INDEX idx_partial VISIBLE;
+SELECT show_index_status('idx_partial');
+
+-- 4. Expression index
+CREATE INDEX idx_expression ON index_test((lower(data)));
+SELECT show_index_status('idx_expression');
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE lower(data) = 'data 500';
+ALTER INDEX idx_expression INVISIBLE;
+SELECT show_index_status('idx_expression');
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE lower(data) = 'data 500';
+ALTER INDEX idx_expression VISIBLE;
+SELECT show_index_status('idx_expression');
+
+-- 5. GIN index
+CREATE INDEX idx_gin ON index_test USING gin(vector);
+SELECT show_index_status('idx_gin');
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE vector @> ARRAY[500];
+ALTER INDEX idx_gin INVISIBLE;
+SELECT show_index_status('idx_gin');
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE vector @> ARRAY[500];
+ALTER INDEX idx_gin VISIBLE;
+SELECT show_index_status('idx_gin');
+
+-- 6. GiST index
+CREATE INDEX idx_gist ON index_test USING gist(range);
+SELECT show_index_status('idx_gist');
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE range && int4range(100, 110);
+ALTER INDEX idx_gist INVISIBLE;
+SELECT show_index_status('idx_gist');
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE range && int4range(100, 110);
+ALTER INDEX idx_gist VISIBLE;
+SELECT show_index_status('idx_gist');
+
+-- 7. Covering index
+CREATE INDEX idx_covering ON index_test(num) INCLUDE (data);
+SELECT show_index_status('idx_covering');
+EXPLAIN (COSTS OFF) SELECT num, data FROM index_test WHERE num = 50;
+ALTER INDEX idx_covering INVISIBLE;
+SELECT show_index_status('idx_covering');
+EXPLAIN (COSTS OFF) SELECT num, data FROM index_test WHERE num = 50;
+ALTER INDEX idx_covering VISIBLE;
+SELECT show_index_status('idx_covering');
+
+-- 8. Unique index
+CREATE UNIQUE INDEX idx_unique ON index_test(id, data);
+SELECT show_index_status('idx_unique');
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE id = 500 AND data = 'data 500';
+ALTER INDEX idx_unique INVISIBLE;
+SELECT show_index_status('idx_unique');
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE id = 500 AND data = 'data 500';
+ALTER INDEX idx_unique VISIBLE;
+SELECT show_index_status('idx_unique');
+
+-- 9. Function-based index
+CREATE INDEX idx_func ON index_test(get_data_length(data));
+SELECT show_index_status('idx_func');
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE get_data_length(data) = 10;
+ALTER INDEX idx_func INVISIBLE;
+SELECT show_index_status('idx_func');
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE get_data_length(data) = 10;
+ALTER INDEX idx_func VISIBLE;
+SELECT show_index_status('idx_func');
+
+-- 10. Join index
+CREATE TABLE join_test (id INT PRIMARY KEY, ref_id INT);
+INSERT INTO join_test SELECT g, g % 100 FROM generate_series(1, 1000) g;
+CREATE INDEX idx_join ON join_test(ref_id);
+SELECT show_index_status('idx_join');
+
+EXPLAIN (COSTS OFF)
+SELECT jt.id, it.data
+FROM join_test jt
+JOIN index_test it ON jt.ref_id = it.num
+WHERE jt.id BETWEEN 100 AND 200;
+
+-- Set all indexes to invisible to force seq scan
+ALTER INDEX idx_join INVISIBLE;
+ALTER INDEX join_test_pkey INVISIBLE;
+SELECT show_index_status('idx_join');
+SELECT show_index_status('join_test_pkey');
+
+EXPLAIN (COSTS OFF)
+SELECT jt.id, it.data
+FROM join_test jt
+JOIN index_test it ON jt.ref_id = it.num
+WHERE jt.id BETWEEN 100 AND 200;
+
+ALTER INDEX idx_join VISIBLE;
+ALTER INDEX join_test_pkey VISIBLE;
+SELECT show_index_status('idx_join');
+SELECT show_index_status('join_test_pkey');
+
+-- Test REINDEX CONCURRENTLY
+REINDEX INDEX CONCURRENTLY idx_join;
+SELECT show_index_status('idx_join');
+
+ALTER INDEX idx_join INVISIBLE;
+SELECT show_index_status('idx_join');
+REINDEX INDEX CONCURRENTLY idx_join;
+SELECT show_index_status('idx_join');
+
+SELECT pg_get_indexdef('idx_join'::regclass);
+ALTER INDEX idx_join VISIBLE;
+SELECT pg_get_indexdef('idx_join'::regclass);
+
+-- Test index visibility with indcheckxmin being true
+
+CREATE TABLE indcheckxmin_test(id int PRIMARY KEY);
+INSERT INTO indcheckxmin_test VALUES (1), (2), (3);
+CREATE INDEX CONCURRENTLY idx_checkxmin ON indcheckxmin_test(id);
+BEGIN;
+-- Simulate indcheckxmin being true
+UPDATE pg_index SET indcheckxmin = true WHERE indexrelid = 'idx_checkxmin'::regclass;
+ALTER INDEX idx_checkxmin INVISIBLE;  -- expect fail
+ROLLBACK;
+
+-- Test prepared statements with index visibility
+CREATE TABLE prep_idx_test (id int, data text);
+CREATE INDEX prep_idx1 ON prep_idx_test(data);
+INSERT INTO prep_idx_test SELECT g, 'data ' || g FROM generate_series(1,100) g;
+
+-- Test with visible index
+PREPARE idx_plan AS SELECT * FROM prep_idx_test WHERE data = $1;
+EXPLAIN (COSTS OFF) EXECUTE idx_plan('data 1');
+EXECUTE idx_plan('data 1');
+
+-- Test with invisible index
+ALTER INDEX prep_idx1 INVISIBLE;
+EXPLAIN (COSTS OFF) EXECUTE idx_plan('data 1');
+EXECUTE idx_plan('data 1');
+
+-- Test with use_invisible_index
+SET use_invisible_index TO on;
+EXPLAIN (COSTS OFF) EXECUTE idx_plan('data 1');
+EXECUTE idx_plan('data 1');
+SET use_invisible_index TO off;
+-- Assert plan cache is reset and index is not used
+EXPLAIN (COSTS OFF) EXECUTE idx_plan('data 1');
+
+-- Make index visible and test again
+ALTER INDEX prep_idx1 VISIBLE;
+EXPLAIN (COSTS OFF) EXECUTE idx_plan('data 1');
+EXECUTE idx_plan('data 1');
+
+-- Clean up
+DROP TABLE index_test;
+DROP TABLE join_test;
+DROP FUNCTION get_data_length;
+DROP FUNCTION show_index_status;
+DROP TABLE indcheckxmin_test CASCADE;
+DEALLOCATE idx_plan;
+DROP TABLE prep_idx_test;
+
 -- Failure for unauthorized user
 CREATE ROLE regress_reindexuser NOLOGIN;
 SET SESSION ROLE regress_reindexuser;
-- 
2.39.5 (Apple Git-154)

#61Benoit Lobréau
benoit.lobreau@gmail.com
In reply to: Shayon Mukherjee (#60)
Re: Proposal to Enable/Disable Index using ALTER INDEX (with patch)

Hi,

Thank you for the patch! I've had a need for this feature several times,
so I appreciate the work you’ve put into it.

I like the new name VISIBLE/INVISIBLE and the fact that it's a separate flag in
pg_index (it's easy to monitor).

I don’t feel qualified to provide an opinion on the code itself just yet.

I did notice something in the command prototype:

+ALTER INDEX [ IF EXISTS ] <replaceable
class="parameter">name</replaceable> VISIBLE
+ALTER INDEX [ IF EXISTS ] <replaceable
class="parameter">name</replaceable> INVISIBLE

it would probably be better as:

+ALTER INDEX [ IF EXISTS ] <replaceable
class="parameter">name</replaceable> {VISIBLE|INVISIBLE}

The completion for the INVISIBLE / VISIBLE keyword is missing in psql.

I also tested the ALTER command within a transaction, and it worked as I
expected: the changes are transactional (possibly because you didn’t use
systable_inplace_update_begin?).

Additionally, I tried using the ALTER command on an index that supports
a foreign key. As expected, delete and update operations on the referenced
table became significantly slower. I was wondering if this behavior should
be documented here.

+      Make the specified index invisible. The index will not be used
for queries.
+      This can be useful for testing query performance with and
without specific
+      indexes.

Maybe something like :

The index will not be used for user or system queries (e.g., an index
supporting foreign keys).

I noticed that you mentionned checking pg_stat_user_indexes before using
the query but it might not be enough?

#62Benoit Lobréau
benoit.lobreau@gmail.com
In reply to: Benoit Lobréau (#61)
Re: Proposal to Enable/Disable Index using ALTER INDEX (with patch)

On Fri, Jan 24, 2025 at 11:32 AM Benoit Lobréau
<benoit.lobreau@gmail.com> wrote:

The completion for the INVISIBLE / VISIBLE keyword is missing in psql.

I think this should to the trick ?

diff --git a/src/bin/psql/tab-complete.in.c b/src/bin/psql/tab-complete.in.c
index 81cbf10aa28..43ea8e55fd0 100644
--- a/src/bin/psql/tab-complete.in.c
+++ b/src/bin/psql/tab-complete.in.c
@@ -2393,7 +2393,8 @@ match_previous_words(int pattern_id,
        else if (Matches("ALTER", "INDEX", MatchAny))
                COMPLETE_WITH("ALTER COLUMN", "OWNER TO", "RENAME TO", "SET",
                                          "RESET", "ATTACH PARTITION",
-                                         "DEPENDS ON EXTENSION", "NO
DEPENDS ON EXTENSION");
+                                         "DEPENDS ON EXTENSION", "NO
DEPENDS ON EXTENSION",
+                                         "INVISIBLE", "VISIBLE");
        else if (Matches("ALTER", "INDEX", MatchAny, "ATTACH"))
                COMPLETE_WITH("PARTITION");
        else if (Matches("ALTER", "INDEX", MatchAny, "ATTACH", "PARTITION"))
#63Benoit Lobréau
benoit.lobreau@gmail.com
In reply to: Benoit Lobréau (#62)
1 attachment(s)
Re: Proposal to Enable/Disable Index using ALTER INDEX (with patch)

I also noticed that \d on an index doesn't warn about the invisible state
whereas \d on a table does:

[local]:5444 postgres@postgres=# SELECT indexrelid::regclass,
indisvalid, indisvisible FROM pg_index WHERE indexrelid =
'repli_pkey'::regclass \gx
-[ RECORD 1 ]+-----------
indexrelid | repli_pkey
indisvalid | f
indisvisible | f

[local]:5444 postgres@postgres=# \d repli_pkey
Index "public.repli_pkey"
Column | Type | Key? | Definition
--------+---------+------+------------
i | integer | yes | i
primary key, btree, for table "public.repli", invalid

[local]:5444 postgres@postgres=# \d repli
Table "public.repli"
Column | Type | Collation | Nullable | Default
--------+---------+-----------+----------+---------
i | integer | | not null |
t | text | | |
Indexes:
"repli_pkey" PRIMARY KEY, btree (i) INVISIBLE INVALID
Publications:
"pub"

The attached patch adds the flag.

[local]:5444 postgres@postgres=# \d repli_pkey
Index "public.repli_pkey"
Column | Type | Key? | Definition
--------+---------+------+------------
i | integer | yes | i
primary key, btree, for table "public.repli", invalid, invisible

Attachments:

0002-Add-the-invisible-tag-for-indexes-in-d.patchtext/x-patch; charset=US-ASCII; name=0002-Add-the-invisible-tag-for-indexes-in-d.patchDownload
From bf3f11e5e88a30a9c1affd9678dadec9bc236351 Mon Sep 17 00:00:00 2001
From: benoit <benoit.lobreau@dalibo.com>
Date: Fri, 24 Jan 2025 16:12:45 +0100
Subject: [PATCH 2/3] Add the invisible tag for indexes in \d

---
 src/bin/psql/describe.c | 15 ++++++++++++---
 1 file changed, 12 insertions(+), 3 deletions(-)

diff --git a/src/bin/psql/describe.c b/src/bin/psql/describe.c
index 2ef99971ac0..5d1acbd149d 100644
--- a/src/bin/psql/describe.c
+++ b/src/bin/psql/describe.c
@@ -2318,6 +2318,11 @@ describeOneTableDetails(const char *schemaname,
 		else
 			appendPQExpBufferStr(&buf, "false AS indnullsnotdistinct,\n");
 
+		if (pset.sversion >= 180000)
+			appendPQExpBufferStr(&buf, "i.indisvisible,\n");
+		else
+			appendPQExpBufferStr(&buf, "true AS indisvisible,\n");
+
 		appendPQExpBuffer(&buf, "  a.amname, c2.relname, "
 						  "pg_catalog.pg_get_expr(i.indpred, i.indrelid, true)\n"
 						  "FROM pg_catalog.pg_index i, pg_catalog.pg_class c, pg_catalog.pg_class c2, pg_catalog.pg_am a\n"
@@ -2343,9 +2348,10 @@ describeOneTableDetails(const char *schemaname,
 			char	   *deferred = PQgetvalue(result, 0, 5);
 			char	   *indisreplident = PQgetvalue(result, 0, 6);
 			char	   *indnullsnotdistinct = PQgetvalue(result, 0, 7);
-			char	   *indamname = PQgetvalue(result, 0, 8);
-			char	   *indtable = PQgetvalue(result, 0, 9);
-			char	   *indpred = PQgetvalue(result, 0, 10);
+			char	   *indisvisible = PQgetvalue(result, 0, 8);
+			char	   *indamname = PQgetvalue(result, 0, 9);
+			char	   *indtable = PQgetvalue(result, 0, 10);
+			char	   *indpred = PQgetvalue(result, 0, 11);
 
 			if (strcmp(indisprimary, "t") == 0)
 				printfPQExpBuffer(&tmpbuf, _("primary key, "));
@@ -2382,6 +2388,9 @@ describeOneTableDetails(const char *schemaname,
 			if (strcmp(indisreplident, "t") == 0)
 				appendPQExpBufferStr(&tmpbuf, _(", replica identity"));
 
+			if (strcmp(indisvisible, "t") != 0)
+				appendPQExpBufferStr(&tmpbuf, _(", invisible"));
+
 			printTableAddFooter(&cont, tmpbuf.data);
 
 			/*
-- 
2.48.1

#64Benoit Lobréau
benoit.lobreau@gmail.com
In reply to: Benoit Lobréau (#63)
Re: Proposal to Enable/Disable Index using ALTER INDEX (with patch)

I did some additional testing with this command within transactions.

I had the "BEGIN; ALTER INDEX; EXPLAIN; ROLLBACK;" scenario in mind, but
didn't realise we acquire an AccessExclusiveLock on the index. Therefore, it's
not possible to change the visibility within a single transaction....
unless you don’t mind blocking all access to the relation.

I read the comments at the top of "AlterTableGetLockLevel" and in the
documentation and I understand that this behavior seems unavoidable.
I suppose this is what was meant by the "globally visible effects" of an ALTER
INDEX in the old discussion ? [1]/messages/by-id/30558.1529359929@sss.pgh.pa.us

Being able to rollback the changes is nice, but in this case there is
not much to alter
back anyway. This is probably not the intended use case (hence the
discussion about
GUCs and hints).

[1]: /messages/by-id/30558.1529359929@sss.pgh.pa.us

#65Sami Imseih
samimseih@gmail.com
In reply to: Benoit Lobréau (#64)
Re: Proposal to Enable/Disable Index using ALTER INDEX (with patch)

I had the "BEGIN; ALTER INDEX; EXPLAIN; ROLLBACK;" scenario in mind, but
didn't realise we acquire an AccessExclusiveLock on the index. Therefore, it's
not possible to change the visibility within a single transaction....
unless you don’t mind blocking all access to the relation.

I read the comments at the top of "AlterTableGetLockLevel" and in the
documentation and I understand that this behavior seems unavoidable.
I suppose this is what was meant by the "globally visible effects" of an ALTER
INDEX in the old discussion ? [1]

What is being discussed here is different from what I can tell. This
is referring
to the index changing status ( visible/invisible ) and those changes being
visible by another transaction.

However, the current patch may be too restrictive. Why do we need
an AccessExclusiveLock on the table to perform the change. We are
only changing the catalog and not the underlying data. This is a lot like
ALTER INDEX RENAME, which only takes a ShareUpdateExclusiveLock.
Can we do the same here?

I am also still reviewing and have a few comments on v9

1/ Missing ATSimpleRecursion call in PrepCmd for
case AT_SetIndexVisible:
case AT_SetIndexInvisible:
Without the recursion call, the visibility changes on a
parent will not apply to the partitions. We are also
missing tests for partitions.

2/ In ATExecSetIndexVisibility

Change:
elog(ERROR, "could not find tuple for index %u", indexOid);

To:
elog(ERROR, "cache lookup failed for index %u", indexOid);

I see both message formats are used all over the place,
but in tablecmds.c, the "cache lookup" variant is the one
used, so let's do that for consistency.

3/ In ATExecSetIndexVisibility

        if (indexForm->indcheckxmin)
+       {
+               heap_freetuple(indexTuple);
+               table_close(pg_index, RowExclusiveLock);
+                ereport(ERROR,

There is no need to close the table or free the tuple, as
these are "cleaned up" when the transaction aborts.

4/ In ATExecSetIndexVisibility

I have a suggestion below:

What about we open both heapOid and IndexRelationId
at the start and close them at the end. Also,
inside the block for indexForm->indisvisible != visible,
do the work to invalidate the cache, invoke the post
alter hook and increment the command counter. This will
also allow us to get rid of the update boolean as well.

What do you think?

Regards,

Sami

#66Shayon Mukherjee
shayonj@gmail.com
In reply to: Sami Imseih (#65)
1 attachment(s)
Re: Proposal to Enable/Disable Index using ALTER INDEX (with patch)

On Fri, Jan 31, 2025 at 10:18 AM Sami Imseih <samimseih@gmail.com> wrote:

What is being discussed here is different from what I can tell. This
is referring
to the index changing status ( visible/invisible ) and those changes being
visible by another transaction.

+1. My vote would be to keep the behavior as is, at least for the first
roll out of this feature.

However, the current patch may be too restrictive. Why do we need
an AccessExclusiveLock on the table to perform the change. We are
only changing the catalog and not the underlying data. This is a lot like
ALTER INDEX RENAME, which only takes a ShareUpdateExclusiveLock.
Can we do the same here?

Makes sense, I think this ended up being a remananent from one of the first
iterations. Updated it in the attached v10 patch.

1/ Missing ATSimpleRecursion call in PrepCmd for
case AT_SetIndexVisible:
case AT_SetIndexInvisible:
Without the recursion call, the visibility changes on a
parent will not apply to the partitions. We are also
missing tests for partitions.

Great catch! Thank you!! Updated the patch with the support for partitions
and backed by regression specs.

2/ In ATExecSetIndexVisibility

Change:
elog(ERROR, "could not find tuple for index %u", indexOid);

To:
elog(ERROR, "cache lookup failed for index %u", indexOid);

Good eye! I missed this :).

3/ In ATExecSetIndexVisibility

if (indexForm->indcheckxmin)
+       {
+               heap_freetuple(indexTuple);
+               table_close(pg_index, RowExclusiveLock);
+                ereport(ERROR,

There is no need to close the table or free the tuple, as
these are "cleaned up" when the transaction aborts.

4/ In ATExecSetIndexVisibility

I have a suggestion below:

What about we open both heapOid and IndexRelationId
at the start and close them at the end. Also,
inside the block for indexForm->indisvisible != visible,
do the work to invalidate the cache, invoke the post
alter hook and increment the command counter. This will
also allow us to get rid of the update boolean as well.

What do you think?

Thank you for the suggestions!! I was err'ing a bit on the "defensive" side
being new to this area, however your suggestions are much more simpler. I
have updated the patch accordingly.

I have also added support for suggestions from the earlier messages, I will
respond there accordingly.

Thank you!
Shayon

Attachments:

v10-0001-Introduce-the-ability-to-set-index-visibility-us.patchapplication/octet-stream; name=v10-0001-Introduce-the-ability-to-set-index-visibility-us.patchDownload
From 1ac78ad9cf653a83008b7e9d6f2a9a20b155a8d1 Mon Sep 17 00:00:00 2001
From: Shayon Mukherjee <shayonj@gmail.com>
Date: Sun, 12 Jan 2025 14:34:48 -0500
Subject: [PATCH v10] Introduce the ability to set index visibility using ALTER
 INDEX

This patch introduces index visibility control using ALTER INDEX and CREATE INDEX
commands.

Original motivation for the problem and proposal for a patch
can be found at [1].

This patch passes all the existing specs and the newly added regression tests. The patch
is ready for review and test. It compiles, so the patch can be applied for testing as well.

Note: The patch has gone through a few iterations. Earlier versions of the patch had the ENABLE/DISABLE grammar.
The current version has the VISIBLE/INVISIBLE grammar. So, you will the local variable names using the new grammar accordingly.

Implementation details:

- New Grammar:
  * ALTER INDEX ... VISIBLE/INVISIBLE
  * CREATE INDEX ... INVISIBLE

- Default state is visible. Indexes are only invisible when explicitly
  instructed via CREATE INDEX ... INVISIBLE or ALTER INDEX ... INVISIBLE.

- Primary Key and Unique constraint indexes are always visible. The
  VISIBLE/INVISIBLE grammar is supported for these types of indexes and they can
  be made invisible via ALTER INDEX ... INVISIBLE.

- ALTER INDEX ... VISIBLE/INVISIBLE performs update on the relevant row in pg_index
  catalog

- pg_get_indexdef() supports the new functionality and grammar. This change is
  reflected in \d output for tables and pg_dump. We show the INVISIBLE syntax accordingly.

- Added force_invisible_index GUC parameter that forces the planner to use invisible
  indexes. This is useful for testing and validating index behavior without changing
  their visibility state. Based on feedback from Sami S [2]

- Updated create_index.sql regression test to cover the new grammar and verify
  that invisible indexes are not used in queries. The test covers:

  - Basic single-column and multi-column indexes
  - Partial indexes
  - Expression indexes
  - Join indexes
  - GIN and GiST indexes
  - Covering indexes
  - Range indexes
  - Unique indexes and constraints

- Adds a new indisvisible attribute to the IndexOptInfo structure.

- Modifies get_relation_info in plancat.c to skip invisible indexes entirely, thus reducing the number of places we need to check if an index is invisible or not. Inspired by the conversations start at [3].
  - I chose to modify the logic within get_relation_info as compared to, say, reducing the cost to make the planner not consider an index during planning, mostly to keep the number of changes being introduced to a minimum and also the logic itself being self-contained and easier to understand perhaps (?).

- No changes are made to stop the index from getting maintained. This way we ensure no
  data loss or corruption when index is made visible again.

- TOAST indexes are supported and visible by default as well.

- REINDEX CONCURRENTLY is supported as well and existing state of pg_index.indisvisible
  is carried over accordingly.

- See the changes in create_index.sql to get an idea of the grammar and sql statements.

- See the changes in create_index.out to get an idea of the catalogue states and EXPLAIN
  output to see when an index is getting used or isn't (when invisible).

- Incorporated DavidR's feedback from [4] around documentation and also you will see that by skipping invisible indexes entirely from get_relation_info in plancat.c (as mentioned above), we address the other mentioned issues as well.

- Lastly, protects against the case where indcheckxmin is true by raising ERRCODE_OBJECT_NOT_IN_PREREQUISITE_STATE.

Looking forward to any and all feedback on this patch, including but not limited to code quality, tests, fundamental logic.

[1] https://www.postgresql.org/message-id/CANqtF-oXKe0M%3D0QOih6H%2BsZRjE2BWAbkW_1%2B9nMEAMLxUJg5jA%40mail.gmail.com
[2] https://www.postgresql.org/message-id/CAA5RZ0udzydObMDi65C59-oq54B9ZmjSZ1wVH3h%2Bv4XiVm6QDA%40mail.gmail.com
[3] https://www.postgresql.org/message-id/3465209.1727202064%40sss.pgh.pa.us
[4] https://www.postgresql.org/message-id/CAApHDvpUNu%3DiVcdJ74sypvgeaCF%2Btfpyb8VRhZaF7DTd1xVr7g%40mail.gmail.com
---
 doc/src/sgml/catalogs.sgml                 |  11 +
 doc/src/sgml/config.sgml                   |  16 +
 doc/src/sgml/ref/alter_index.sgml          |  38 ++
 doc/src/sgml/ref/create_index.sgml         |  29 +
 src/backend/bootstrap/bootparse.y          |   2 +
 src/backend/catalog/index.c                |  31 +-
 src/backend/catalog/toasting.c             |   2 +-
 src/backend/commands/indexcmds.c           |   4 +
 src/backend/commands/tablecmds.c           |  66 +-
 src/backend/optimizer/util/plancat.c       |  31 +-
 src/backend/parser/gram.y                  |  56 +-
 src/backend/parser/parse_utilcmd.c         |   3 +
 src/backend/utils/adt/ruleutils.c          |   4 +
 src/backend/utils/cache/relcache.c         |   1 +
 src/backend/utils/misc/guc_tables.c        |  11 +
 src/bin/psql/tab-complete.in.c             |   3 +-
 src/include/catalog/index.h                |   2 +-
 src/include/catalog/pg_index.h             |   1 +
 src/include/nodes/parsenodes.h             |   3 +
 src/include/optimizer/optimizer.h          |   5 +
 src/include/parser/kwlist.h                |   2 +
 src/include/utils/guc_hooks.h              |   1 +
 src/test/regress/expected/create_index.out | 705 +++++++++++++++++++++
 src/test/regress/sql/create_index.sql      | 291 +++++++++
 24 files changed, 1298 insertions(+), 20 deletions(-)

diff --git a/doc/src/sgml/catalogs.sgml b/doc/src/sgml/catalogs.sgml
index 088fb175cc..8b0019d0e6 100644
--- a/doc/src/sgml/catalogs.sgml
+++ b/doc/src/sgml/catalogs.sgml
@@ -4595,6 +4595,17 @@ SCRAM-SHA-256$<replaceable>&lt;iteration count&gt;</replaceable>:<replaceable>&l
        partial index.
       </para></entry>
      </row>
+
+     <row>
+      <entry role="catalog_table_entry"><para role="column_definition">
+       <structfield>indisvisible</structfield> <type>bool</type>
+      </para>
+      <para>
+       If true, the index is currently visible to the planner and may be used for queries.
+       If false, the index is invisible and may not be used for queries,
+       but is still updated when the table is modified. Default is true.
+      </para></entry>
+     </row>
     </tbody>
    </tgroup>
   </table>
diff --git a/doc/src/sgml/config.sgml b/doc/src/sgml/config.sgml
index a782f10998..873fae9a93 100644
--- a/doc/src/sgml/config.sgml
+++ b/doc/src/sgml/config.sgml
@@ -5589,6 +5589,22 @@ ANY <replaceable class="parameter">num_sync</replaceable> ( <replaceable class="
       </listitem>
      </varlistentry>
 
+     <varlistentry id="guc-force-invisible-index" xreflabel="use_invisible_index">
+      <term><varname>use_invisible_index</varname> (<type>boolean</type>)
+      <indexterm>
+       <primary><varname>use_invisible_index</varname> configuration parameter</primary>
+      </indexterm>
+      </term>
+      <listitem>
+       <para>
+        Forces the query planner to consider indexes that have been marked as invisible using
+        <command>ALTER INDEX ... INVISIBLE</command>. This parameter is useful for selective
+        use of invisible indexes in specific application contexts. The default
+        is <literal>off</literal>.
+       </para>
+      </listitem>
+     </varlistentry>
+
      </variablelist>
      </sect2>
      <sect2 id="runtime-config-query-constants">
diff --git a/doc/src/sgml/ref/alter_index.sgml b/doc/src/sgml/ref/alter_index.sgml
index 1d42d05d85..eaaa40d54c 100644
--- a/doc/src/sgml/ref/alter_index.sgml
+++ b/doc/src/sgml/ref/alter_index.sgml
@@ -31,6 +31,7 @@ ALTER INDEX [ IF EXISTS ] <replaceable class="parameter">name</replaceable> ALTE
     SET STATISTICS <replaceable class="parameter">integer</replaceable>
 ALTER INDEX ALL IN TABLESPACE <replaceable class="parameter">name</replaceable> [ OWNED BY <replaceable class="parameter">role_name</replaceable> [, ... ] ]
     SET TABLESPACE <replaceable class="parameter">new_tablespace</replaceable> [ NOWAIT ]
+ALTER INDEX [ IF EXISTS ] <replaceable class="parameter">name</replaceable> { VISIBLE | INVISIBLE }
 </synopsis>
  </refsynopsisdiv>
 
@@ -159,6 +160,29 @@ ALTER INDEX ALL IN TABLESPACE <replaceable class="parameter">name</replaceable>
     </listitem>
    </varlistentry>
 
+   <varlistentry>
+    <term><literal>VISIBLE</literal></term>
+    <listitem>
+     <para>
+      Make the specified index visible. The index will be used for queries.
+     </para>
+    </listitem>
+   </varlistentry>
+
+   <varlistentry>
+    <term><literal>INVISIBLE</literal></term>
+    <listitem>
+     <para>
+      Make the specified index invisible. The index will not be used for queries.
+      This can be useful for testing query performance with and without specific
+      indexes. If performance degrades after making an index invisible, it can be easily
+      be made visible using <literal>VISIBLE</literal>. Before making an index invisible, it's recommended
+      to check <structname>pg_stat_user_indexes</structname>.<structfield>idx_scan</structfield>
+      to identify potentially unused indexes.
+     </para>
+    </listitem>
+   </varlistentry>
+
   </variablelist>
   </para>
 
@@ -301,6 +325,20 @@ CREATE INDEX coord_idx ON measured (x, y, (z + t));
 ALTER INDEX coord_idx ALTER COLUMN 3 SET STATISTICS 1000;
 </programlisting></para>
 
+  <para>
+   To make an index visible:
+<programlisting>
+ALTER INDEX idx_name VISIBLE;
+</programlisting>
+  </para>
+
+  <para>
+   To make an index invisible:
+<programlisting>
+ALTER INDEX idx_name INVISIBLE;
+</programlisting>
+  </para>
+
  </refsect1>
 
  <refsect1>
diff --git a/doc/src/sgml/ref/create_index.sgml b/doc/src/sgml/ref/create_index.sgml
index 208389e800..90d7d90a2b 100644
--- a/doc/src/sgml/ref/create_index.sgml
+++ b/doc/src/sgml/ref/create_index.sgml
@@ -28,6 +28,7 @@ CREATE [ UNIQUE ] INDEX [ CONCURRENTLY ] [ [ IF NOT EXISTS ] <replaceable class=
     [ WITH ( <replaceable class="parameter">storage_parameter</replaceable> [= <replaceable class="parameter">value</replaceable>] [, ... ] ) ]
     [ TABLESPACE <replaceable class="parameter">tablespace_name</replaceable> ]
     [ WHERE <replaceable class="parameter">predicate</replaceable> ]
+    [ INVISIBLE ]
 </synopsis>
  </refsynopsisdiv>
 
@@ -380,6 +381,19 @@ CREATE [ UNIQUE ] INDEX [ CONCURRENTLY ] [ [ IF NOT EXISTS ] <replaceable class=
       </listitem>
      </varlistentry>
 
+    <varlistentry>
+      <term><literal>INVISIBLE</literal></term>
+      <listitem>
+       <para>
+        Creates the index in an invisible state (default visible). An invisible index is
+        not used by the query planner for queries, but it is still maintained
+        when the underlying table data changes. This can be useful when you want to create
+        an index without immediately impacting query planning, allowing you to make it
+        visible later at a more convenient time. The index can be made visible later
+        using <command>ALTER INDEX ... VISIBLE</command>.
+       </para>
+      </listitem>
+     </varlistentry>
     </variablelist>
 
   <refsect2 id="sql-createindex-storage-parameters" xreflabel="Index Storage Parameters">
@@ -701,6 +715,14 @@ Indexes:
     partitioned index is a metadata only operation.
    </para>
 
+  <para>
+   When creating an index with the <literal>INVISIBLE</literal> option, the index
+   will be created but not used for query planning. This can be useful for
+   preparing an index in advance of its use, or for testing purposes. The index
+   will still be maintained as the table is modified, so it can be made visible
+   later without needing to be rebuilt. By default all new indexes are visible.
+  </para>
+
   </refsect2>
  </refsect1>
 
@@ -980,6 +1002,13 @@ SELECT * FROM points
 CREATE INDEX CONCURRENTLY sales_quantity_index ON sales_table (quantity);
 </programlisting></para>
 
+  <para>
+   To create an index on the table <literal>test_table</literal> with the default
+   name, but have it initially invisible:
+<programlisting>
+CREATE INDEX ON test_table (col1) INVISIBLE;
+</programlisting>
+  </para>
  </refsect1>
 
  <refsect1>
diff --git a/src/backend/bootstrap/bootparse.y b/src/backend/bootstrap/bootparse.y
index 9833f52c1b..ea21511a20 100644
--- a/src/backend/bootstrap/bootparse.y
+++ b/src/backend/bootstrap/bootparse.y
@@ -303,6 +303,7 @@ Boot_DeclareIndexStmt:
 					stmt->concurrent = false;
 					stmt->if_not_exists = false;
 					stmt->reset_default_tblspc = false;
+					stmt->isvisible = true;
 
 					/* locks and races need not concern us in bootstrap mode */
 					relationId = RangeVarGetRelid(stmt->relation, NoLock,
@@ -356,6 +357,7 @@ Boot_DeclareUniqueIndexStmt:
 					stmt->concurrent = false;
 					stmt->if_not_exists = false;
 					stmt->reset_default_tblspc = false;
+					stmt->isvisible = true;
 
 					/* locks and races need not concern us in bootstrap mode */
 					relationId = RangeVarGetRelid(stmt->relation, NoLock,
diff --git a/src/backend/catalog/index.c b/src/backend/catalog/index.c
index 7377912b41..ef51e6de0b 100644
--- a/src/backend/catalog/index.c
+++ b/src/backend/catalog/index.c
@@ -118,7 +118,8 @@ static void UpdateIndexRelation(Oid indexoid, Oid heapoid,
 								bool isexclusion,
 								bool immediate,
 								bool isvalid,
-								bool isready);
+								bool isready,
+								bool isvisible);
 static void index_update_stats(Relation rel,
 							   bool hasindex,
 							   double reltuples);
@@ -570,7 +571,8 @@ UpdateIndexRelation(Oid indexoid,
 					bool isexclusion,
 					bool immediate,
 					bool isvalid,
-					bool isready)
+					bool isready,
+					bool isvisible)
 {
 	int2vector *indkey;
 	oidvector  *indcollation;
@@ -648,6 +650,7 @@ UpdateIndexRelation(Oid indexoid,
 	values[Anum_pg_index_indisready - 1] = BoolGetDatum(isready);
 	values[Anum_pg_index_indislive - 1] = BoolGetDatum(true);
 	values[Anum_pg_index_indisreplident - 1] = BoolGetDatum(false);
+	values[Anum_pg_index_indisvisible - 1] = BoolGetDatum(isvisible);
 	values[Anum_pg_index_indkey - 1] = PointerGetDatum(indkey);
 	values[Anum_pg_index_indcollation - 1] = PointerGetDatum(indcollation);
 	values[Anum_pg_index_indclass - 1] = PointerGetDatum(indclass);
@@ -713,6 +716,8 @@ UpdateIndexRelation(Oid indexoid,
  *			already exists.
  *		INDEX_CREATE_PARTITIONED:
  *			create a partitioned index (table must be partitioned)
+ *		INDEX_CREATE_VISIBLE:
+ *			create the index as visible to query planner
  * constr_flags: flags passed to index_constraint_create
  *		(only if INDEX_CREATE_ADD_CONSTRAINT is set)
  * allow_system_table_mods: allow table to be a system catalog
@@ -758,6 +763,7 @@ index_create(Relation heapRelation,
 	bool		invalid = (flags & INDEX_CREATE_INVALID) != 0;
 	bool		concurrent = (flags & INDEX_CREATE_CONCURRENT) != 0;
 	bool		partitioned = (flags & INDEX_CREATE_PARTITIONED) != 0;
+	bool 		isvisible  = (flags & INDEX_CREATE_VISIBLE) != 0;
 	char		relkind;
 	TransactionId relfrozenxid;
 	MultiXactId relminmxid;
@@ -1041,13 +1047,15 @@ index_create(Relation heapRelation,
 	 *	  (Or, could define a rule to maintain the predicate) --Nels, Feb '92
 	 * ----------------
 	 */
+
 	UpdateIndexRelation(indexRelationId, heapRelationId, parentIndexRelid,
 						indexInfo,
 						collationIds, opclassIds, coloptions,
 						isprimary, is_exclusion,
 						(constr_flags & INDEX_CONSTR_CREATE_DEFERRABLE) == 0,
 						!concurrent && !invalid,
-						!concurrent);
+						!concurrent,
+						isvisible);
 
 	/*
 	 * Register relcache invalidation on the indexes' heap relation, to
@@ -1316,6 +1324,8 @@ index_concurrently_create_copy(Relation heapRelation, Oid oldIndexId,
 	List	   *indexColNames = NIL;
 	List	   *indexExprs = NIL;
 	List	   *indexPreds = NIL;
+	Form_pg_index indexForm;
+	bits16 	 createFlags;
 
 	indexRelation = index_open(oldIndexId, RowExclusiveLock);
 
@@ -1343,6 +1353,9 @@ index_concurrently_create_copy(Relation heapRelation, Oid oldIndexId,
 											Anum_pg_index_indoption);
 	indcoloptions = (int2vector *) DatumGetPointer(colOptionDatum);
 
+	/* Get the visibility state of the original index */
+	indexForm = (Form_pg_index) GETSTRUCT(indexTuple);
+
 	/* Fetch reloptions of index if any */
 	classTuple = SearchSysCache1(RELOID, ObjectIdGetDatum(oldIndexId));
 	if (!HeapTupleIsValid(classTuple))
@@ -1434,6 +1447,16 @@ index_concurrently_create_copy(Relation heapRelation, Oid oldIndexId,
 		stattargets[i].isnull = isnull;
 	}
 
+	/*
+	* Determine the create flags for the new index.
+	* We always use SKIP_BUILD and CONCURRENT for concurrent reindexing.
+	* If the original index was visible, we also set the VISIBLE flag
+	* to maintain the same state in the new index.
+	*/
+	createFlags = INDEX_CREATE_SKIP_BUILD | INDEX_CREATE_CONCURRENT;
+	if (indexForm->indisvisible)
+			createFlags |= INDEX_CREATE_VISIBLE;
+
 	/*
 	 * Now create the new index.
 	 *
@@ -1457,7 +1480,7 @@ index_concurrently_create_copy(Relation heapRelation, Oid oldIndexId,
 							  indcoloptions->values,
 							  stattargets,
 							  reloptionsDatum,
-							  INDEX_CREATE_SKIP_BUILD | INDEX_CREATE_CONCURRENT,
+							  createFlags,
 							  0,
 							  true, /* allow table to be a system catalog? */
 							  false,	/* is_internal? */
diff --git a/src/backend/catalog/toasting.c b/src/backend/catalog/toasting.c
index 874a8fc89a..7721d16fd3 100644
--- a/src/backend/catalog/toasting.c
+++ b/src/backend/catalog/toasting.c
@@ -325,7 +325,7 @@ create_toast_table(Relation rel, Oid toastOid, Oid toastIndexOid,
 				 BTREE_AM_OID,
 				 rel->rd_rel->reltablespace,
 				 collationIds, opclassIds, NULL, coloptions, NULL, (Datum) 0,
-				 INDEX_CREATE_IS_PRIMARY, 0, true, true, NULL);
+				 INDEX_CREATE_IS_PRIMARY | INDEX_CREATE_VISIBLE, 0, true, true, NULL);
 
 	table_close(toast_rel, NoLock);
 
diff --git a/src/backend/commands/indexcmds.c b/src/backend/commands/indexcmds.c
index 59c836fc24..9e86ea413b 100644
--- a/src/backend/commands/indexcmds.c
+++ b/src/backend/commands/indexcmds.c
@@ -1198,6 +1198,10 @@ DefineIndex(Oid tableId,
 		flags |= INDEX_CREATE_PARTITIONED;
 	if (stmt->primary)
 		flags |= INDEX_CREATE_IS_PRIMARY;
+   if (stmt->isvisible)
+		flags |= INDEX_CREATE_VISIBLE;
+   else
+		flags &= ~INDEX_CREATE_VISIBLE;
 
 	/*
 	 * If the table is partitioned, and recursion was declined but partitions
diff --git a/src/backend/commands/tablecmds.c b/src/backend/commands/tablecmds.c
index d617c4bc63..b975e83a13 100644
--- a/src/backend/commands/tablecmds.c
+++ b/src/backend/commands/tablecmds.c
@@ -700,7 +700,7 @@ static List *GetParentedForeignKeyRefs(Relation partition);
 static void ATDetachCheckNoForeignKeyRefs(Relation partition);
 static char GetAttributeCompression(Oid atttypid, const char *compression);
 static char GetAttributeStorage(Oid atttypid, const char *storagemode);
-
+static void ATExecSetIndexVisibility(Relation rel, bool visible);
 
 /* ----------------------------------------------------------------
  *		DefineRelation
@@ -4789,6 +4789,11 @@ AlterTableGetLockLevel(List *cmds)
 				cmd_lockmode = ShareUpdateExclusiveLock;
 				break;
 
+			case AT_SetIndexVisible:
+			case AT_SetIndexInvisible:
+				cmd_lockmode = ShareUpdateExclusiveLock;
+				break;
+
 			default:			/* oops */
 				elog(ERROR, "unrecognized alter table type: %d",
 					 (int) cmd->subtype);
@@ -5222,6 +5227,13 @@ ATPrepCmd(List **wqueue, Relation rel, AlterTableCmd *cmd,
 			/* No command-specific prep needed */
 			pass = AT_PASS_MISC;
 			break;
+		case AT_SetIndexVisible:
+		case AT_SetIndexInvisible:
+			ATSimplePermissions(cmd->subtype, rel, ATT_INDEX | ATT_PARTITIONED_INDEX);
+			ATSimpleRecursion(wqueue, rel, cmd, true, lockmode, context);
+			/* No command-specific prep needed */
+			pass = AT_PASS_MISC;
+			break;
 		default:				/* oops */
 			elog(ERROR, "unrecognized alter table type: %d",
 				 (int) cmd->subtype);
@@ -5616,6 +5628,12 @@ ATExecCmd(List **wqueue, AlteredTableInfo *tab,
 		case AT_DetachPartitionFinalize:
 			address = ATExecDetachPartitionFinalize(rel, ((PartitionCmd *) cmd->def)->name);
 			break;
+		case AT_SetIndexVisible:
+				ATExecSetIndexVisibility(rel, true);
+				break;
+		case AT_SetIndexInvisible:
+				ATExecSetIndexVisibility(rel, false);
+				break;
 		default:				/* oops */
 			elog(ERROR, "unrecognized alter table type: %d",
 				 (int) cmd->subtype);
@@ -6510,6 +6528,8 @@ alter_table_type_to_string(AlterTableType cmdtype)
 			return "DROP COLUMN";
 		case AT_AddIndex:
 		case AT_ReAddIndex:
+		case AT_SetIndexVisible:
+		case AT_SetIndexInvisible:
 			return NULL;		/* not real grammar */
 		case AT_AddConstraint:
 		case AT_ReAddConstraint:
@@ -21050,3 +21070,47 @@ GetAttributeStorage(Oid atttypid, const char *storagemode)
 
 	return cstorage;
 }
+
+/*
+ * ATExecSetIndexVisibility
+ * Performs a catalog update to mark an index as visible or invisible in pg_index.
+ */
+static void
+ATExecSetIndexVisibility(Relation rel, bool visible)
+{
+	Oid			indexOid = RelationGetRelid(rel);
+	Oid			heapOid;
+	Relation	pg_index;
+	Relation	heapRel;
+	HeapTuple	indexTuple;
+	Form_pg_index	indexForm;
+
+	heapOid = IndexGetRelation(indexOid, false);
+	heapRel = table_open(heapOid, AccessShareLock);
+	pg_index = table_open(IndexRelationId, RowExclusiveLock);
+
+	indexTuple = SearchSysCacheCopy1(INDEXRELID, ObjectIdGetDatum(indexOid));
+	if (!HeapTupleIsValid(indexTuple))
+		elog(ERROR, "cache lookup failed for index %u", indexOid);
+
+	indexForm = (Form_pg_index) GETSTRUCT(indexTuple);
+	if (indexForm->indcheckxmin)
+		ereport(ERROR,
+				(errcode(ERRCODE_OBJECT_NOT_IN_PREREQUISITE_STATE),
+				errmsg("cannot update index visibility while indcheckxmin is true"),
+				errhint("Wait for all transactions that might see inconsistent HOT chains to complete")));
+
+	if (indexForm->indisvisible != visible)
+	{
+		indexForm->indisvisible = visible;
+		CatalogTupleUpdate(pg_index, &indexTuple->t_self, indexTuple);
+
+		CacheInvalidateRelcache(heapRel);
+		InvokeObjectPostAlterHook(IndexRelationId, indexOid, 0);
+		CommandCounterIncrement();
+	}
+
+	heap_freetuple(indexTuple);
+	table_close(pg_index, RowExclusiveLock);
+	table_close(heapRel, AccessShareLock);
+}
diff --git a/src/backend/optimizer/util/plancat.c b/src/backend/optimizer/util/plancat.c
index 71abb01f65..0b0682b505 100644
--- a/src/backend/optimizer/util/plancat.c
+++ b/src/backend/optimizer/util/plancat.c
@@ -47,7 +47,9 @@
 #include "storage/bufmgr.h"
 #include "tcop/tcopprot.h"
 #include "utils/builtins.h"
+#include "utils/guc_hooks.h"
 #include "utils/lsyscache.h"
+#include "utils/plancache.h"
 #include "utils/partcache.h"
 #include "utils/rel.h"
 #include "utils/snapmgr.h"
@@ -55,6 +57,7 @@
 
 /* GUC parameter */
 int			constraint_exclusion = CONSTRAINT_EXCLUSION_PARTITION;
+bool		use_invisible_index = false;
 
 /* Hook for plugins to get control in get_relation_info() */
 get_relation_info_hook_type get_relation_info_hook = NULL;
@@ -254,13 +257,12 @@ get_relation_info(PlannerInfo *root, Oid relationObjectId, bool inhparent,
 			index = indexRelation->rd_index;
 
 			/*
-			 * Ignore invalid indexes, since they can't safely be used for
-			 * queries.  Note that this is OK because the data structure we
-			 * are constructing is only used by the planner --- the executor
-			 * still needs to insert into "invalid" indexes, if they're marked
-			 * indisready.
-			 */
-			if (!index->indisvalid)
+			 * Skip invalid indexes, and invisible indexes unless use_invisible_index
+			 * is set. This is OK because the data structure we are constructing is
+			 * only used by the planner - the executor still needs to insert into
+			 * these indexes if they're marked indisready.
+			*/
+			if (!index->indisvalid || (!index->indisvisible && !use_invisible_index))
 			{
 				index_close(indexRelation, NoLock);
 				continue;
@@ -2610,3 +2612,18 @@ set_baserel_partition_constraint(Relation relation, RelOptInfo *rel)
 		rel->partition_qual = partconstr;
 	}
 }
+
+/*
+ * assign_use_invisible_index
+ * GUC assign_hook for "use_invisible_index" GUC variable.
+ * Resets the plan cache when the value changes.
+ */
+void
+assign_use_invisible_index(bool newval, void *extra)
+{
+	if (use_invisible_index != newval)
+	{
+		use_invisible_index = newval;
+		ResetPlanCache();
+	}
+}
diff --git a/src/backend/parser/gram.y b/src/backend/parser/gram.y
index d7f9c00c40..475ee26036 100644
--- a/src/backend/parser/gram.y
+++ b/src/backend/parser/gram.y
@@ -324,7 +324,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 %type <ival>	add_drop opt_asc_desc opt_nulls_order
 
 %type <node>	alter_table_cmd alter_type_cmd opt_collate_clause
-	   replica_identity partition_cmd index_partition_cmd
+	   replica_identity partition_cmd index_partition_cmd index_alter_cmd
 %type <list>	alter_table_cmds alter_type_cmds
 %type <list>    alter_identity_column_option_list
 %type <defelt>  alter_identity_column_option
@@ -491,6 +491,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 %type <boolean> opt_unique opt_verbose opt_full
 %type <boolean> opt_freeze opt_analyze opt_default
 %type <defelt>	opt_binary copy_delimiter
+%type <boolean>  opt_index_visibility
 
 %type <boolean> copy_from opt_program
 
@@ -733,7 +734,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 	IDENTITY_P IF_P ILIKE IMMEDIATE IMMUTABLE IMPLICIT_P IMPORT_P IN_P INCLUDE
 	INCLUDING INCREMENT INDENT INDEX INDEXES INHERIT INHERITS INITIALLY INLINE_P
 	INNER_P INOUT INPUT_P INSENSITIVE INSERT INSTEAD INT_P INTEGER
-	INTERSECT INTERVAL INTO INVOKER IS ISNULL ISOLATION
+	INTERSECT INTERVAL INTO INVISIBLE_P INVOKER IS ISNULL ISOLATION
 
 	JOIN JSON JSON_ARRAY JSON_ARRAYAGG JSON_EXISTS JSON_OBJECT JSON_OBJECTAGG
 	JSON_QUERY JSON_SCALAR JSON_SERIALIZE JSON_TABLE JSON_VALUE
@@ -784,7 +785,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 	UNLISTEN UNLOGGED UNTIL UPDATE USER USING
 
 	VACUUM VALID VALIDATE VALIDATOR VALUE_P VALUES VARCHAR VARIADIC VARYING
-	VERBOSE VERSION_P VIEW VIEWS VOLATILE
+	VERBOSE VERSION_P VIEW VIEWS VISIBLE_P VOLATILE
 
 	WHEN WHERE WHITESPACE_P WINDOW WITH WITHIN WITHOUT WORK WRAPPER WRITE
 
@@ -2157,6 +2158,24 @@ AlterTableStmt:
 					n->nowait = $13;
 					$$ = (Node *) n;
 				}
+		| ALTER INDEX qualified_name index_alter_cmd
+				{
+					AlterTableStmt *n = makeNode(AlterTableStmt);
+					n->relation = $3;
+					n->cmds = list_make1($4);
+					n->objtype = OBJECT_INDEX;
+					n->missing_ok = false;
+					$$ = (Node *) n;
+				}
+		| ALTER INDEX IF_P EXISTS qualified_name index_alter_cmd
+				{
+					AlterTableStmt *n = makeNode(AlterTableStmt);
+					n->relation = $5;
+					n->cmds = list_make1($6);
+					n->objtype = OBJECT_INDEX;
+					n->missing_ok = true;
+					$$ = (Node *) n;
+				}
 		|	ALTER INDEX qualified_name alter_table_cmds
 				{
 					AlterTableStmt *n = makeNode(AlterTableStmt);
@@ -2382,6 +2401,21 @@ index_partition_cmd:
 				}
 		;
 
+index_alter_cmd:
+		/* ALTER INDEX <name> VISIBLE|INVISIBLE */
+		VISIBLE_P
+			{
+				AlterTableCmd *n = makeNode(AlterTableCmd);
+				n->subtype = AT_SetIndexVisible;
+				$$ = (Node *) n;
+			}
+		| INVISIBLE_P
+			{
+				AlterTableCmd *n = makeNode(AlterTableCmd);
+				n->subtype = AT_SetIndexInvisible;
+				$$ = (Node *) n;
+			}
+		;
 alter_table_cmd:
 			/* ALTER TABLE <name> ADD <coldef> */
 			ADD_P columnDef
@@ -8160,7 +8194,7 @@ defacl_privilege_target:
 
 IndexStmt:	CREATE opt_unique INDEX opt_concurrently opt_single_name
 			ON relation_expr access_method_clause '(' index_params ')'
-			opt_include opt_unique_null_treatment opt_reloptions OptTableSpace where_clause
+			opt_include opt_unique_null_treatment opt_reloptions OptTableSpace where_clause opt_index_visibility
 				{
 					IndexStmt *n = makeNode(IndexStmt);
 
@@ -8175,6 +8209,7 @@ IndexStmt:	CREATE opt_unique INDEX opt_concurrently opt_single_name
 					n->options = $14;
 					n->tableSpace = $15;
 					n->whereClause = $16;
+					n->isvisible = $17;
 					n->excludeOpNames = NIL;
 					n->idxcomment = NULL;
 					n->indexOid = InvalidOid;
@@ -8192,7 +8227,7 @@ IndexStmt:	CREATE opt_unique INDEX opt_concurrently opt_single_name
 				}
 			| CREATE opt_unique INDEX opt_concurrently IF_P NOT EXISTS name
 			ON relation_expr access_method_clause '(' index_params ')'
-			opt_include opt_unique_null_treatment opt_reloptions OptTableSpace where_clause
+			opt_include opt_unique_null_treatment opt_reloptions OptTableSpace where_clause opt_index_visibility
 				{
 					IndexStmt *n = makeNode(IndexStmt);
 
@@ -8207,6 +8242,7 @@ IndexStmt:	CREATE opt_unique INDEX opt_concurrently opt_single_name
 					n->options = $17;
 					n->tableSpace = $18;
 					n->whereClause = $19;
+					n->isvisible = $20;
 					n->excludeOpNames = NIL;
 					n->idxcomment = NULL;
 					n->indexOid = InvalidOid;
@@ -8229,6 +8265,12 @@ opt_unique:
 			| /*EMPTY*/								{ $$ = false; }
 		;
 
+opt_index_visibility:
+			VISIBLE_P                      { $$ = true; }
+			| INVISIBLE_P                   { $$ = false; }
+			| /*EMPTY*/                 	{ $$ = true; }
+		;
+
 access_method_clause:
 			USING name								{ $$ = $2; }
 			| /*EMPTY*/								{ $$ = DEFAULT_INDEX_TYPE; }
@@ -17806,6 +17848,7 @@ unreserved_keyword:
 			| INSENSITIVE
 			| INSERT
 			| INSTEAD
+			| INVISIBLE_P
 			| INVOKER
 			| ISOLATION
 			| KEEP
@@ -17990,6 +18033,7 @@ unreserved_keyword:
 			| VERSION_P
 			| VIEW
 			| VIEWS
+			|	VISIBLE_P
 			| VOLATILE
 			| WHITESPACE_P
 			| WITHIN
@@ -18399,6 +18443,7 @@ bare_label_keyword:
 			| INT_P
 			| INTEGER
 			| INTERVAL
+			| INVISIBLE_P
 			| INVOKER
 			| IS
 			| ISOLATION
@@ -18645,6 +18690,7 @@ bare_label_keyword:
 			| VERSION_P
 			| VIEW
 			| VIEWS
+			| VISIBLE_P
 			| VOLATILE
 			| WHEN
 			| WHITESPACE_P
diff --git a/src/backend/parser/parse_utilcmd.c b/src/backend/parser/parse_utilcmd.c
index ca028d2a66..9cd8a65b52 100644
--- a/src/backend/parser/parse_utilcmd.c
+++ b/src/backend/parser/parse_utilcmd.c
@@ -1743,6 +1743,7 @@ generateClonedIndexStmt(RangeVar *heapRel, Relation source_idx,
 	index->concurrent = false;
 	index->if_not_exists = false;
 	index->reset_default_tblspc = false;
+	index->isvisible = idxrec->indisvisible;
 
 	/*
 	 * We don't try to preserve the name of the source index; instead, just
@@ -2364,6 +2365,8 @@ transformIndexConstraint(Constraint *constraint, CreateStmtContext *cxt)
 	index->concurrent = false;
 	index->if_not_exists = false;
 	index->reset_default_tblspc = constraint->reset_default_tblspc;
+	/* Ensure indexes for constraints are created as visible by default */
+	index->isvisible = true;
 
 	/*
 	 * If it's ALTER TABLE ADD CONSTRAINT USING INDEX, look up the index and
diff --git a/src/backend/utils/adt/ruleutils.c b/src/backend/utils/adt/ruleutils.c
index 54dad97555..a46780de87 100644
--- a/src/backend/utils/adt/ruleutils.c
+++ b/src/backend/utils/adt/ruleutils.c
@@ -1562,6 +1562,10 @@ pg_get_indexdef_worker(Oid indexrelid, int colno,
 			else
 				appendStringInfo(&buf, " WHERE %s", str);
 		}
+
+		/* Add INVISIBLE clause if the index is invisible */
+		if (!idxrec->indisvisible)
+				appendStringInfoString(&buf, " INVISIBLE");
 	}
 
 	/* Clean up */
diff --git a/src/backend/utils/cache/relcache.c b/src/backend/utils/cache/relcache.c
index 43219a9629..8c084622eb 100644
--- a/src/backend/utils/cache/relcache.c
+++ b/src/backend/utils/cache/relcache.c
@@ -2311,6 +2311,7 @@ RelationReloadIndexInfo(Relation relation)
 		relation->rd_index->indisready = index->indisready;
 		relation->rd_index->indislive = index->indislive;
 		relation->rd_index->indisreplident = index->indisreplident;
+		relation->rd_index->indisvisible = index->indisvisible;
 
 		/* Copy xmin too, as that is needed to make sense of indcheckxmin */
 		HeapTupleHeaderSetXmin(relation->rd_indextuple->t_data,
diff --git a/src/backend/utils/misc/guc_tables.c b/src/backend/utils/misc/guc_tables.c
index 0bdfc83907..9699ceebed 100644
--- a/src/backend/utils/misc/guc_tables.c
+++ b/src/backend/utils/misc/guc_tables.c
@@ -2096,6 +2096,17 @@ struct config_bool ConfigureNamesBool[] =
 		NULL, NULL, NULL
 	},
 
+	{
+		{"use_invisible_index", PGC_USERSET, QUERY_TUNING_OTHER,
+			gettext_noop("Forces the planner to consider invisible indexes."),
+			NULL,
+			GUC_NOT_IN_SAMPLE | GUC_EXPLAIN
+		},
+		&use_invisible_index,
+		false,
+		NULL, assign_use_invisible_index, NULL
+	},
+
 	/* End-of-list marker */
 	{
 		{NULL, 0, 0, NULL, NULL}, NULL, false, NULL, NULL, NULL
diff --git a/src/bin/psql/tab-complete.in.c b/src/bin/psql/tab-complete.in.c
index 81cbf10aa2..43ea8e55fd 100644
--- a/src/bin/psql/tab-complete.in.c
+++ b/src/bin/psql/tab-complete.in.c
@@ -2393,7 +2393,8 @@ match_previous_words(int pattern_id,
 	else if (Matches("ALTER", "INDEX", MatchAny))
 		COMPLETE_WITH("ALTER COLUMN", "OWNER TO", "RENAME TO", "SET",
 					  "RESET", "ATTACH PARTITION",
-					  "DEPENDS ON EXTENSION", "NO DEPENDS ON EXTENSION");
+					  "DEPENDS ON EXTENSION", "NO DEPENDS ON EXTENSION",
+					  "INVISIBLE", "VISIBLE");
 	else if (Matches("ALTER", "INDEX", MatchAny, "ATTACH"))
 		COMPLETE_WITH("PARTITION");
 	else if (Matches("ALTER", "INDEX", MatchAny, "ATTACH", "PARTITION"))
diff --git a/src/include/catalog/index.h b/src/include/catalog/index.h
index 4daa8bef5e..ff0f9916de 100644
--- a/src/include/catalog/index.h
+++ b/src/include/catalog/index.h
@@ -65,6 +65,7 @@ extern void index_check_primary_key(Relation heapRel,
 #define	INDEX_CREATE_IF_NOT_EXISTS			(1 << 4)
 #define	INDEX_CREATE_PARTITIONED			(1 << 5)
 #define INDEX_CREATE_INVALID				(1 << 6)
+#define INDEX_CREATE_VISIBLE        (1 << 7)
 
 extern Oid	index_create(Relation heapRelation,
 						 const char *indexRelationName,
@@ -175,7 +176,6 @@ extern void RestoreReindexState(const void *reindexstate);
 
 extern void IndexSetParentIndex(Relation partitionIdx, Oid parentOid);
 
-
 /*
  * itemptr_encode - Encode ItemPointer as int64/int8
  *
diff --git a/src/include/catalog/pg_index.h b/src/include/catalog/pg_index.h
index 4392b9d221..cf1bea9c81 100644
--- a/src/include/catalog/pg_index.h
+++ b/src/include/catalog/pg_index.h
@@ -44,6 +44,7 @@ CATALOG(pg_index,2610,IndexRelationId) BKI_SCHEMA_MACRO
 	bool		indisready;		/* is this index ready for inserts? */
 	bool		indislive;		/* is this index alive at all? */
 	bool		indisreplident; /* is this index the identity for replication? */
+	bool		indisvisible BKI_DEFAULT(t);	/* is this index visible for use by queries? */
 
 	/* variable-length fields start here, but we allow direct access to indkey */
 	int2vector	indkey BKI_FORCE_NOT_NULL;	/* column numbers of indexed cols,
diff --git a/src/include/nodes/parsenodes.h b/src/include/nodes/parsenodes.h
index ffe155ee20..e9553d0f24 100644
--- a/src/include/nodes/parsenodes.h
+++ b/src/include/nodes/parsenodes.h
@@ -2467,6 +2467,8 @@ typedef enum AlterTableType
 	AT_SetIdentity,				/* SET identity column options */
 	AT_DropIdentity,			/* DROP IDENTITY */
 	AT_ReAddStatistics,			/* internal to commands/tablecmds.c */
+	AT_SetIndexVisible,					/* Set INDEX visible */
+	AT_SetIndexInvisible,				/* Set INDEX invisible */
 } AlterTableType;
 
 typedef struct ReplicaIdentityStmt
@@ -3449,6 +3451,7 @@ typedef struct IndexStmt
 	bool		if_not_exists;	/* just do nothing if index already exists? */
 	bool		reset_default_tblspc;	/* reset default_tablespace prior to
 										 * executing */
+  bool		isvisible;		/* true if VISIBLE (default), false if INVISIBLE */
 } IndexStmt;
 
 /* ----------------------
diff --git a/src/include/optimizer/optimizer.h b/src/include/optimizer/optimizer.h
index bcf8ed645c..99e435076a 100644
--- a/src/include/optimizer/optimizer.h
+++ b/src/include/optimizer/optimizer.h
@@ -205,4 +205,9 @@ extern List *pull_var_clause(Node *node, int flags);
 extern Node *flatten_join_alias_vars(PlannerInfo *root, Query *query, Node *node);
 extern Node *flatten_group_exprs(PlannerInfo *root, Query *query, Node *node);
 
+/*
+ * GUC to tell planner to consider invisible indexes.
+ */
+extern bool use_invisible_index;
+
 #endif							/* OPTIMIZER_H */
diff --git a/src/include/parser/kwlist.h b/src/include/parser/kwlist.h
index cf2917ad07..18b97aefb0 100644
--- a/src/include/parser/kwlist.h
+++ b/src/include/parser/kwlist.h
@@ -229,6 +229,7 @@ PG_KEYWORD("integer", INTEGER, COL_NAME_KEYWORD, BARE_LABEL)
 PG_KEYWORD("intersect", INTERSECT, RESERVED_KEYWORD, AS_LABEL)
 PG_KEYWORD("interval", INTERVAL, COL_NAME_KEYWORD, BARE_LABEL)
 PG_KEYWORD("into", INTO, RESERVED_KEYWORD, AS_LABEL)
+PG_KEYWORD("invisible", INVISIBLE_P, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("invoker", INVOKER, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("is", IS, TYPE_FUNC_NAME_KEYWORD, BARE_LABEL)
 PG_KEYWORD("isnull", ISNULL, TYPE_FUNC_NAME_KEYWORD, AS_LABEL)
@@ -491,6 +492,7 @@ PG_KEYWORD("verbose", VERBOSE, TYPE_FUNC_NAME_KEYWORD, BARE_LABEL)
 PG_KEYWORD("version", VERSION_P, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("view", VIEW, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("views", VIEWS, UNRESERVED_KEYWORD, BARE_LABEL)
+PG_KEYWORD("visible", VISIBLE_P, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("volatile", VOLATILE, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("when", WHEN, RESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("where", WHERE, RESERVED_KEYWORD, AS_LABEL)
diff --git a/src/include/utils/guc_hooks.h b/src/include/utils/guc_hooks.h
index 87999218d6..909f9b57ed 100644
--- a/src/include/utils/guc_hooks.h
+++ b/src/include/utils/guc_hooks.h
@@ -174,5 +174,6 @@ extern void assign_wal_sync_method(int new_wal_sync_method, void *extra);
 extern bool check_synchronized_standby_slots(char **newval, void **extra,
 											 GucSource source);
 extern void assign_synchronized_standby_slots(const char *newval, void *extra);
+extern void assign_use_invisible_index(bool newval, void *extra);
 
 #endif							/* GUC_HOOKS_H */
diff --git a/src/test/regress/expected/create_index.out b/src/test/regress/expected/create_index.out
index 8011c141bf..66201b888b 100644
--- a/src/test/regress/expected/create_index.out
+++ b/src/test/regress/expected/create_index.out
@@ -3331,6 +3331,711 @@ ERROR:  REINDEX SCHEMA cannot run inside a transaction block
 END;
 -- concurrently
 REINDEX SCHEMA CONCURRENTLY schema_to_reindex;
+-- Test index visibility functionality
+CREATE TABLE index_test(
+    id INT PRIMARY KEY,
+    data TEXT,
+    num INT,
+    vector INT[],
+    range INT4RANGE
+);
+INSERT INTO index_test
+SELECT
+    g,
+    'data ' || g,
+    g % 100,
+    ARRAY[g, g+1, g+2],
+    int4range(g, g+10)
+FROM generate_series(1, 1000) g;
+-- Function for testing
+CREATE FUNCTION get_data_length(text) RETURNS INT AS $$
+    SELECT length($1);
+$$ LANGUAGE SQL IMMUTABLE;
+-- Helper function to show index status
+CREATE OR REPLACE FUNCTION show_index_status(index_name text)
+RETURNS TABLE (
+    indexrelid regclass,
+    indisvalid boolean,
+    indisready boolean,
+    indislive boolean,
+    indisvisible boolean
+) AS $$
+BEGIN
+    RETURN QUERY EXECUTE format('
+        SELECT indexrelid::regclass, indisvalid, indisready, indislive, indisvisible
+        FROM pg_index
+        WHERE indexrelid = %L::regclass', index_name);
+END;
+$$ LANGUAGE plpgsql;
+-- Create and test each index type
+-- 1. Basic single-column index
+CREATE INDEX idx_single ON index_test(data);
+SELECT show_index_status('idx_single');
+  show_index_status   
+----------------------
+ (idx_single,t,t,t,t)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE data = 'data 500';
+                  QUERY PLAN                   
+-----------------------------------------------
+ Bitmap Heap Scan on index_test
+   Recheck Cond: (data = 'data 500'::text)
+   ->  Bitmap Index Scan on idx_single
+         Index Cond: (data = 'data 500'::text)
+(4 rows)
+
+ALTER INDEX idx_single INVISIBLE;
+SELECT show_index_status('idx_single');
+  show_index_status   
+----------------------
+ (idx_single,t,t,t,f)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE data = 'data 500';
+             QUERY PLAN              
+-------------------------------------
+ Seq Scan on index_test
+   Filter: (data = 'data 500'::text)
+(2 rows)
+
+ALTER INDEX idx_single VISIBLE;
+SELECT show_index_status('idx_single');
+  show_index_status   
+----------------------
+ (idx_single,t,t,t,t)
+(1 row)
+
+-- 2. Multi-column index
+CREATE INDEX idx_multi ON index_test(num, data);
+SELECT show_index_status('idx_multi');
+  show_index_status  
+---------------------
+ (idx_multi,t,t,t,t)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE num = 50 AND data > 'data 500';
+                           QUERY PLAN                           
+----------------------------------------------------------------
+ Bitmap Heap Scan on index_test
+   Recheck Cond: ((num = 50) AND (data > 'data 500'::text))
+   ->  Bitmap Index Scan on idx_multi
+         Index Cond: ((num = 50) AND (data > 'data 500'::text))
+(4 rows)
+
+ALTER INDEX idx_multi INVISIBLE;
+SELECT show_index_status('idx_multi');
+  show_index_status  
+---------------------
+ (idx_multi,t,t,t,f)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE num = 50 AND data > 'data 500';
+                      QUERY PLAN                      
+------------------------------------------------------
+ Seq Scan on index_test
+   Filter: ((data > 'data 500'::text) AND (num = 50))
+(2 rows)
+
+ALTER INDEX idx_multi VISIBLE;
+SELECT show_index_status('idx_multi');
+  show_index_status  
+---------------------
+ (idx_multi,t,t,t,t)
+(1 row)
+
+-- 3. Partial index
+CREATE INDEX idx_partial ON index_test(num) WHERE num < 50;
+SELECT show_index_status('idx_partial');
+   show_index_status   
+-----------------------
+ (idx_partial,t,t,t,t)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE num = 25;
+               QUERY PLAN               
+----------------------------------------
+ Bitmap Heap Scan on index_test
+   Recheck Cond: (num = 25)
+   ->  Bitmap Index Scan on idx_partial
+         Index Cond: (num = 25)
+(4 rows)
+
+ALTER INDEX idx_partial INVISIBLE;
+SELECT show_index_status('idx_partial');
+   show_index_status   
+-----------------------
+ (idx_partial,t,t,t,f)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE num = 25;
+              QUERY PLAN              
+--------------------------------------
+ Bitmap Heap Scan on index_test
+   Recheck Cond: (num = 25)
+   ->  Bitmap Index Scan on idx_multi
+         Index Cond: (num = 25)
+(4 rows)
+
+ALTER INDEX idx_partial VISIBLE;
+SELECT show_index_status('idx_partial');
+   show_index_status   
+-----------------------
+ (idx_partial,t,t,t,t)
+(1 row)
+
+-- 4. Expression index
+CREATE INDEX idx_expression ON index_test((lower(data)));
+SELECT show_index_status('idx_expression');
+    show_index_status     
+--------------------------
+ (idx_expression,t,t,t,t)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE lower(data) = 'data 500';
+                      QUERY PLAN                      
+------------------------------------------------------
+ Bitmap Heap Scan on index_test
+   Recheck Cond: (lower(data) = 'data 500'::text)
+   ->  Bitmap Index Scan on idx_expression
+         Index Cond: (lower(data) = 'data 500'::text)
+(4 rows)
+
+ALTER INDEX idx_expression INVISIBLE;
+SELECT show_index_status('idx_expression');
+    show_index_status     
+--------------------------
+ (idx_expression,t,t,t,f)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE lower(data) = 'data 500';
+                 QUERY PLAN                 
+--------------------------------------------
+ Seq Scan on index_test
+   Filter: (lower(data) = 'data 500'::text)
+(2 rows)
+
+ALTER INDEX idx_expression VISIBLE;
+SELECT show_index_status('idx_expression');
+    show_index_status     
+--------------------------
+ (idx_expression,t,t,t,t)
+(1 row)
+
+-- 5. GIN index
+CREATE INDEX idx_gin ON index_test USING gin(vector);
+SELECT show_index_status('idx_gin');
+ show_index_status 
+-------------------
+ (idx_gin,t,t,t,t)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE vector @> ARRAY[500];
+                     QUERY PLAN                     
+----------------------------------------------------
+ Bitmap Heap Scan on index_test
+   Recheck Cond: (vector @> '{500}'::integer[])
+   ->  Bitmap Index Scan on idx_gin
+         Index Cond: (vector @> '{500}'::integer[])
+(4 rows)
+
+ALTER INDEX idx_gin INVISIBLE;
+SELECT show_index_status('idx_gin');
+ show_index_status 
+-------------------
+ (idx_gin,t,t,t,f)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE vector @> ARRAY[500];
+                QUERY PLAN                
+------------------------------------------
+ Seq Scan on index_test
+   Filter: (vector @> '{500}'::integer[])
+(2 rows)
+
+ALTER INDEX idx_gin VISIBLE;
+SELECT show_index_status('idx_gin');
+ show_index_status 
+-------------------
+ (idx_gin,t,t,t,t)
+(1 row)
+
+-- 6. GiST index
+CREATE INDEX idx_gist ON index_test USING gist(range);
+SELECT show_index_status('idx_gist');
+ show_index_status  
+--------------------
+ (idx_gist,t,t,t,t)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE range && int4range(100, 110);
+                      QUERY PLAN                       
+-------------------------------------------------------
+ Bitmap Heap Scan on index_test
+   Recheck Cond: (range && '[100,110)'::int4range)
+   ->  Bitmap Index Scan on idx_gist
+         Index Cond: (range && '[100,110)'::int4range)
+(4 rows)
+
+ALTER INDEX idx_gist INVISIBLE;
+SELECT show_index_status('idx_gist');
+ show_index_status  
+--------------------
+ (idx_gist,t,t,t,f)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE range && int4range(100, 110);
+                 QUERY PLAN                  
+---------------------------------------------
+ Seq Scan on index_test
+   Filter: (range && '[100,110)'::int4range)
+(2 rows)
+
+ALTER INDEX idx_gist VISIBLE;
+SELECT show_index_status('idx_gist');
+ show_index_status  
+--------------------
+ (idx_gist,t,t,t,t)
+(1 row)
+
+-- 7. Covering index
+CREATE INDEX idx_covering ON index_test(num) INCLUDE (data);
+SELECT show_index_status('idx_covering');
+   show_index_status    
+------------------------
+ (idx_covering,t,t,t,t)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT num, data FROM index_test WHERE num = 50;
+               QUERY PLAN                
+-----------------------------------------
+ Bitmap Heap Scan on index_test
+   Recheck Cond: (num = 50)
+   ->  Bitmap Index Scan on idx_covering
+         Index Cond: (num = 50)
+(4 rows)
+
+ALTER INDEX idx_covering INVISIBLE;
+SELECT show_index_status('idx_covering');
+   show_index_status    
+------------------------
+ (idx_covering,t,t,t,f)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT num, data FROM index_test WHERE num = 50;
+              QUERY PLAN              
+--------------------------------------
+ Bitmap Heap Scan on index_test
+   Recheck Cond: (num = 50)
+   ->  Bitmap Index Scan on idx_multi
+         Index Cond: (num = 50)
+(4 rows)
+
+ALTER INDEX idx_covering VISIBLE;
+SELECT show_index_status('idx_covering');
+   show_index_status    
+------------------------
+ (idx_covering,t,t,t,t)
+(1 row)
+
+-- 8. Unique index
+CREATE UNIQUE INDEX idx_unique ON index_test(id, data);
+SELECT show_index_status('idx_unique');
+  show_index_status   
+----------------------
+ (idx_unique,t,t,t,t)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE id = 500 AND data = 'data 500';
+                        QUERY PLAN                        
+----------------------------------------------------------
+ Index Scan using idx_unique on index_test
+   Index Cond: ((id = 500) AND (data = 'data 500'::text))
+(2 rows)
+
+ALTER INDEX idx_unique INVISIBLE;
+SELECT show_index_status('idx_unique');
+  show_index_status   
+----------------------
+ (idx_unique,t,t,t,f)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE id = 500 AND data = 'data 500';
+                   QUERY PLAN                   
+------------------------------------------------
+ Index Scan using index_test_pkey on index_test
+   Index Cond: (id = 500)
+   Filter: (data = 'data 500'::text)
+(3 rows)
+
+ALTER INDEX idx_unique VISIBLE;
+SELECT show_index_status('idx_unique');
+  show_index_status   
+----------------------
+ (idx_unique,t,t,t,t)
+(1 row)
+
+-- 9. Function-based index
+CREATE INDEX idx_func ON index_test(get_data_length(data));
+SELECT show_index_status('idx_func');
+ show_index_status  
+--------------------
+ (idx_func,t,t,t,t)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE get_data_length(data) = 10;
+               QUERY PLAN                
+-----------------------------------------
+ Bitmap Heap Scan on index_test
+   Recheck Cond: (length(data) = 10)
+   ->  Bitmap Index Scan on idx_func
+         Index Cond: (length(data) = 10)
+(4 rows)
+
+ALTER INDEX idx_func INVISIBLE;
+SELECT show_index_status('idx_func');
+ show_index_status  
+--------------------
+ (idx_func,t,t,t,f)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE get_data_length(data) = 10;
+          QUERY PLAN           
+-------------------------------
+ Seq Scan on index_test
+   Filter: (length(data) = 10)
+(2 rows)
+
+ALTER INDEX idx_func VISIBLE;
+SELECT show_index_status('idx_func');
+ show_index_status  
+--------------------
+ (idx_func,t,t,t,t)
+(1 row)
+
+-- 10. Join index
+CREATE TABLE join_test (id INT PRIMARY KEY, ref_id INT);
+INSERT INTO join_test SELECT g, g % 100 FROM generate_series(1, 1000) g;
+CREATE INDEX idx_join ON join_test(ref_id);
+SELECT show_index_status('idx_join');
+ show_index_status  
+--------------------
+ (idx_join,t,t,t,t)
+(1 row)
+
+EXPLAIN (COSTS OFF)
+SELECT jt.id, it.data
+FROM join_test jt
+JOIN index_test it ON jt.ref_id = it.num
+WHERE jt.id BETWEEN 100 AND 200;
+                          QUERY PLAN                           
+---------------------------------------------------------------
+ Hash Join
+   Hash Cond: (it.num = jt.ref_id)
+   ->  Seq Scan on index_test it
+   ->  Hash
+         ->  Bitmap Heap Scan on join_test jt
+               Recheck Cond: ((id >= 100) AND (id <= 200))
+               ->  Bitmap Index Scan on join_test_pkey
+                     Index Cond: ((id >= 100) AND (id <= 200))
+(8 rows)
+
+-- Set all indexes to invisible to force seq scan
+ALTER INDEX idx_join INVISIBLE;
+ALTER INDEX join_test_pkey INVISIBLE;
+SELECT show_index_status('idx_join');
+ show_index_status  
+--------------------
+ (idx_join,t,t,t,f)
+(1 row)
+
+SELECT show_index_status('join_test_pkey');
+    show_index_status     
+--------------------------
+ (join_test_pkey,t,t,t,f)
+(1 row)
+
+EXPLAIN (COSTS OFF)
+SELECT jt.id, it.data
+FROM join_test jt
+JOIN index_test it ON jt.ref_id = it.num
+WHERE jt.id BETWEEN 100 AND 200;
+                     QUERY PLAN                      
+-----------------------------------------------------
+ Hash Join
+   Hash Cond: (it.num = jt.ref_id)
+   ->  Seq Scan on index_test it
+   ->  Hash
+         ->  Seq Scan on join_test jt
+               Filter: ((id >= 100) AND (id <= 200))
+(6 rows)
+
+ALTER INDEX idx_join VISIBLE;
+ALTER INDEX join_test_pkey VISIBLE;
+SELECT show_index_status('idx_join');
+ show_index_status  
+--------------------
+ (idx_join,t,t,t,t)
+(1 row)
+
+SELECT show_index_status('join_test_pkey');
+    show_index_status     
+--------------------------
+ (join_test_pkey,t,t,t,t)
+(1 row)
+
+-- Test REINDEX CONCURRENTLY
+REINDEX INDEX CONCURRENTLY idx_join;
+SELECT show_index_status('idx_join');
+ show_index_status  
+--------------------
+ (idx_join,t,t,t,t)
+(1 row)
+
+ALTER INDEX idx_join INVISIBLE;
+SELECT show_index_status('idx_join');
+ show_index_status  
+--------------------
+ (idx_join,t,t,t,f)
+(1 row)
+
+REINDEX INDEX CONCURRENTLY idx_join;
+SELECT show_index_status('idx_join');
+ show_index_status  
+--------------------
+ (idx_join,t,t,t,f)
+(1 row)
+
+SELECT pg_get_indexdef('idx_join'::regclass);
+                                   pg_get_indexdef                                   
+-------------------------------------------------------------------------------------
+ CREATE INDEX idx_join ON schema_to_reindex.join_test USING btree (ref_id) INVISIBLE
+(1 row)
+
+ALTER INDEX idx_join VISIBLE;
+SELECT pg_get_indexdef('idx_join'::regclass);
+                              pg_get_indexdef                              
+---------------------------------------------------------------------------
+ CREATE INDEX idx_join ON schema_to_reindex.join_test USING btree (ref_id)
+(1 row)
+
+-- Test index visibility with indcheckxmin being true
+CREATE TABLE indcheckxmin_test(id int PRIMARY KEY);
+INSERT INTO indcheckxmin_test VALUES (1), (2), (3);
+CREATE INDEX CONCURRENTLY idx_checkxmin ON indcheckxmin_test(id);
+BEGIN;
+-- Simulate indcheckxmin being true
+UPDATE pg_index SET indcheckxmin = true WHERE indexrelid = 'idx_checkxmin'::regclass;
+ALTER INDEX idx_checkxmin INVISIBLE;  -- expect fail
+ERROR:  cannot update index visibility while indcheckxmin is true
+HINT:  Wait for all transactions that might see inconsistent HOT chains to complete
+ROLLBACK;
+-- Test prepared statements with index visibility
+CREATE TABLE prep_idx_test (id int, data text);
+CREATE INDEX prep_idx1 ON prep_idx_test(data);
+INSERT INTO prep_idx_test SELECT g, 'data ' || g FROM generate_series(1,100) g;
+-- Test with visible index
+PREPARE idx_plan AS SELECT * FROM prep_idx_test WHERE data = $1;
+EXPLAIN (COSTS OFF) EXECUTE idx_plan('data 1');
+                 QUERY PLAN                  
+---------------------------------------------
+ Bitmap Heap Scan on prep_idx_test
+   Recheck Cond: (data = 'data 1'::text)
+   ->  Bitmap Index Scan on prep_idx1
+         Index Cond: (data = 'data 1'::text)
+(4 rows)
+
+EXECUTE idx_plan('data 1');
+ id |  data  
+----+--------
+  1 | data 1
+(1 row)
+
+-- Test with invisible index
+ALTER INDEX prep_idx1 INVISIBLE;
+EXPLAIN (COSTS OFF) EXECUTE idx_plan('data 1');
+            QUERY PLAN             
+-----------------------------------
+ Seq Scan on prep_idx_test
+   Filter: (data = 'data 1'::text)
+(2 rows)
+
+EXECUTE idx_plan('data 1');
+ id |  data  
+----+--------
+  1 | data 1
+(1 row)
+
+-- Test with use_invisible_index
+SET use_invisible_index TO on;
+EXPLAIN (COSTS OFF) EXECUTE idx_plan('data 1');
+                 QUERY PLAN                  
+---------------------------------------------
+ Bitmap Heap Scan on prep_idx_test
+   Recheck Cond: (data = 'data 1'::text)
+   ->  Bitmap Index Scan on prep_idx1
+         Index Cond: (data = 'data 1'::text)
+(4 rows)
+
+EXECUTE idx_plan('data 1');
+ id |  data  
+----+--------
+  1 | data 1
+(1 row)
+
+SET use_invisible_index TO off;
+-- Assert plan cache is reset and index is not used
+EXPLAIN (COSTS OFF) EXECUTE idx_plan('data 1');
+            QUERY PLAN             
+-----------------------------------
+ Seq Scan on prep_idx_test
+   Filter: (data = 'data 1'::text)
+(2 rows)
+
+-- Make index visible and test again
+ALTER INDEX prep_idx1 VISIBLE;
+EXPLAIN (COSTS OFF) EXECUTE idx_plan('data 1');
+                 QUERY PLAN                  
+---------------------------------------------
+ Bitmap Heap Scan on prep_idx_test
+   Recheck Cond: (data = 'data 1'::text)
+   ->  Bitmap Index Scan on prep_idx1
+         Index Cond: (data = 'data 1'::text)
+(4 rows)
+
+EXECUTE idx_plan('data 1');
+ id |  data  
+----+--------
+  1 | data 1
+(1 row)
+
+-- Test index visibility with partitioned tables
+CREATE TABLE part_tbl(id int, data text) PARTITION BY RANGE(id);
+CREATE TABLE part1 PARTITION OF part_tbl FOR VALUES FROM (1) TO (100);
+CREATE TABLE part2 PARTITION OF part_tbl FOR VALUES FROM (100) TO (200);
+INSERT INTO part_tbl
+SELECT g, 'data ' || g
+FROM generate_series(1, 199) g;
+CREATE INDEX idx_part_tbl ON part_tbl(data);
+SELECT c.relname, i.indisvisible
+FROM pg_index i
+JOIN pg_class c ON i.indexrelid = c.oid
+WHERE c.relname LIKE 'idx_part_tbl%'
+ORDER BY c.relname;
+   relname    | indisvisible 
+--------------+--------------
+ idx_part_tbl | t
+(1 row)
+
+-- Force use of indexes to avoid flaky test results
+SET enable_seqscan = off;
+EXPLAIN (COSTS OFF)
+SELECT * FROM part_tbl WHERE data = 'data 50';
+                        QUERY PLAN                         
+-----------------------------------------------------------
+ Append
+   ->  Index Scan using part1_data_idx on part1 part_tbl_1
+         Index Cond: (data = 'data 50'::text)
+   ->  Index Scan using part2_data_idx on part2 part_tbl_2
+         Index Cond: (data = 'data 50'::text)
+(5 rows)
+
+ALTER INDEX idx_part_tbl INVISIBLE;
+SELECT c.relname, i.indisvisible
+FROM pg_index i
+JOIN pg_class c ON i.indexrelid = c.oid
+WHERE c.relname LIKE 'idx_part_tbl%'
+ORDER BY c.relname;
+   relname    | indisvisible 
+--------------+--------------
+ idx_part_tbl | f
+(1 row)
+
+-- Check query plan after setting invisible (should use seq scan)
+EXPLAIN (COSTS OFF)
+SELECT * FROM part_tbl WHERE data = 'data 50';
+                QUERY PLAN                
+------------------------------------------
+ Append
+   ->  Seq Scan on part1 part_tbl_1
+         Disabled: true
+         Filter: (data = 'data 50'::text)
+   ->  Seq Scan on part2 part_tbl_2
+         Disabled: true
+         Filter: (data = 'data 50'::text)
+(7 rows)
+
+SET use_invisible_index TO on;
+EXPLAIN (COSTS OFF)
+SELECT * FROM part_tbl WHERE data = 'data 50';
+                        QUERY PLAN                         
+-----------------------------------------------------------
+ Append
+   ->  Index Scan using part1_data_idx on part1 part_tbl_1
+         Index Cond: (data = 'data 50'::text)
+   ->  Index Scan using part2_data_idx on part2 part_tbl_2
+         Index Cond: (data = 'data 50'::text)
+(5 rows)
+
+SET use_invisible_index TO off;
+EXPLAIN (COSTS OFF)
+SELECT * FROM part_tbl WHERE data = 'data 50';
+                QUERY PLAN                
+------------------------------------------
+ Append
+   ->  Seq Scan on part1 part_tbl_1
+         Disabled: true
+         Filter: (data = 'data 50'::text)
+   ->  Seq Scan on part2 part_tbl_2
+         Disabled: true
+         Filter: (data = 'data 50'::text)
+(7 rows)
+
+ALTER INDEX idx_part_tbl VISIBLE;
+SELECT c.relname, i.indisvisible
+FROM pg_index i
+JOIN pg_class c ON i.indexrelid = c.oid
+WHERE c.relname LIKE 'idx_part_tbl%'
+ORDER BY c.relname;
+   relname    | indisvisible 
+--------------+--------------
+ idx_part_tbl | t
+(1 row)
+
+EXPLAIN (COSTS OFF)
+SELECT * FROM part_tbl WHERE data = 'data 50';
+                        QUERY PLAN                         
+-----------------------------------------------------------
+ Append
+   ->  Index Scan using part1_data_idx on part1 part_tbl_1
+         Index Cond: (data = 'data 50'::text)
+   ->  Index Scan using part2_data_idx on part2 part_tbl_2
+         Index Cond: (data = 'data 50'::text)
+(5 rows)
+
+SET enable_seqscan = on;
+-- Test REINDEX maintains visibility setting
+ALTER INDEX idx_part_tbl INVISIBLE;
+REINDEX INDEX idx_part_tbl;
+SELECT c.relname, i.indisvisible
+FROM pg_index i
+JOIN pg_class c ON i.indexrelid = c.oid
+WHERE c.relname LIKE 'idx_part_tbl%'
+ORDER BY c.relname;
+   relname    | indisvisible 
+--------------+--------------
+ idx_part_tbl | f
+(1 row)
+
+-- Clean up
+DROP TABLE index_test;
+DROP TABLE join_test;
+DROP FUNCTION get_data_length;
+DROP FUNCTION show_index_status;
+DROP TABLE indcheckxmin_test CASCADE;
+DEALLOCATE idx_plan;
+DROP TABLE prep_idx_test;
+DROP TABLE part_tbl CASCADE;
 -- Failure for unauthorized user
 CREATE ROLE regress_reindexuser NOLOGIN;
 SET SESSION ROLE regress_reindexuser;
diff --git a/src/test/regress/sql/create_index.sql b/src/test/regress/sql/create_index.sql
index 068c66b95a..2e6293eda0 100644
--- a/src/test/regress/sql/create_index.sql
+++ b/src/test/regress/sql/create_index.sql
@@ -1415,6 +1415,297 @@ END;
 -- concurrently
 REINDEX SCHEMA CONCURRENTLY schema_to_reindex;
 
+-- Test index visibility functionality
+
+CREATE TABLE index_test(
+    id INT PRIMARY KEY,
+    data TEXT,
+    num INT,
+    vector INT[],
+    range INT4RANGE
+);
+
+INSERT INTO index_test
+SELECT
+    g,
+    'data ' || g,
+    g % 100,
+    ARRAY[g, g+1, g+2],
+    int4range(g, g+10)
+FROM generate_series(1, 1000) g;
+
+-- Function for testing
+CREATE FUNCTION get_data_length(text) RETURNS INT AS $$
+    SELECT length($1);
+$$ LANGUAGE SQL IMMUTABLE;
+
+-- Helper function to show index status
+CREATE OR REPLACE FUNCTION show_index_status(index_name text)
+RETURNS TABLE (
+    indexrelid regclass,
+    indisvalid boolean,
+    indisready boolean,
+    indislive boolean,
+    indisvisible boolean
+) AS $$
+BEGIN
+    RETURN QUERY EXECUTE format('
+        SELECT indexrelid::regclass, indisvalid, indisready, indislive, indisvisible
+        FROM pg_index
+        WHERE indexrelid = %L::regclass', index_name);
+END;
+$$ LANGUAGE plpgsql;
+
+-- Create and test each index type
+-- 1. Basic single-column index
+CREATE INDEX idx_single ON index_test(data);
+SELECT show_index_status('idx_single');
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE data = 'data 500';
+ALTER INDEX idx_single INVISIBLE;
+SELECT show_index_status('idx_single');
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE data = 'data 500';
+ALTER INDEX idx_single VISIBLE;
+SELECT show_index_status('idx_single');
+
+-- 2. Multi-column index
+CREATE INDEX idx_multi ON index_test(num, data);
+SELECT show_index_status('idx_multi');
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE num = 50 AND data > 'data 500';
+ALTER INDEX idx_multi INVISIBLE;
+SELECT show_index_status('idx_multi');
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE num = 50 AND data > 'data 500';
+ALTER INDEX idx_multi VISIBLE;
+SELECT show_index_status('idx_multi');
+
+-- 3. Partial index
+CREATE INDEX idx_partial ON index_test(num) WHERE num < 50;
+SELECT show_index_status('idx_partial');
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE num = 25;
+ALTER INDEX idx_partial INVISIBLE;
+SELECT show_index_status('idx_partial');
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE num = 25;
+ALTER INDEX idx_partial VISIBLE;
+SELECT show_index_status('idx_partial');
+
+-- 4. Expression index
+CREATE INDEX idx_expression ON index_test((lower(data)));
+SELECT show_index_status('idx_expression');
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE lower(data) = 'data 500';
+ALTER INDEX idx_expression INVISIBLE;
+SELECT show_index_status('idx_expression');
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE lower(data) = 'data 500';
+ALTER INDEX idx_expression VISIBLE;
+SELECT show_index_status('idx_expression');
+
+-- 5. GIN index
+CREATE INDEX idx_gin ON index_test USING gin(vector);
+SELECT show_index_status('idx_gin');
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE vector @> ARRAY[500];
+ALTER INDEX idx_gin INVISIBLE;
+SELECT show_index_status('idx_gin');
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE vector @> ARRAY[500];
+ALTER INDEX idx_gin VISIBLE;
+SELECT show_index_status('idx_gin');
+
+-- 6. GiST index
+CREATE INDEX idx_gist ON index_test USING gist(range);
+SELECT show_index_status('idx_gist');
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE range && int4range(100, 110);
+ALTER INDEX idx_gist INVISIBLE;
+SELECT show_index_status('idx_gist');
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE range && int4range(100, 110);
+ALTER INDEX idx_gist VISIBLE;
+SELECT show_index_status('idx_gist');
+
+-- 7. Covering index
+CREATE INDEX idx_covering ON index_test(num) INCLUDE (data);
+SELECT show_index_status('idx_covering');
+EXPLAIN (COSTS OFF) SELECT num, data FROM index_test WHERE num = 50;
+ALTER INDEX idx_covering INVISIBLE;
+SELECT show_index_status('idx_covering');
+EXPLAIN (COSTS OFF) SELECT num, data FROM index_test WHERE num = 50;
+ALTER INDEX idx_covering VISIBLE;
+SELECT show_index_status('idx_covering');
+
+-- 8. Unique index
+CREATE UNIQUE INDEX idx_unique ON index_test(id, data);
+SELECT show_index_status('idx_unique');
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE id = 500 AND data = 'data 500';
+ALTER INDEX idx_unique INVISIBLE;
+SELECT show_index_status('idx_unique');
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE id = 500 AND data = 'data 500';
+ALTER INDEX idx_unique VISIBLE;
+SELECT show_index_status('idx_unique');
+
+-- 9. Function-based index
+CREATE INDEX idx_func ON index_test(get_data_length(data));
+SELECT show_index_status('idx_func');
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE get_data_length(data) = 10;
+ALTER INDEX idx_func INVISIBLE;
+SELECT show_index_status('idx_func');
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE get_data_length(data) = 10;
+ALTER INDEX idx_func VISIBLE;
+SELECT show_index_status('idx_func');
+
+-- 10. Join index
+CREATE TABLE join_test (id INT PRIMARY KEY, ref_id INT);
+INSERT INTO join_test SELECT g, g % 100 FROM generate_series(1, 1000) g;
+CREATE INDEX idx_join ON join_test(ref_id);
+SELECT show_index_status('idx_join');
+
+EXPLAIN (COSTS OFF)
+SELECT jt.id, it.data
+FROM join_test jt
+JOIN index_test it ON jt.ref_id = it.num
+WHERE jt.id BETWEEN 100 AND 200;
+
+-- Set all indexes to invisible to force seq scan
+ALTER INDEX idx_join INVISIBLE;
+ALTER INDEX join_test_pkey INVISIBLE;
+SELECT show_index_status('idx_join');
+SELECT show_index_status('join_test_pkey');
+
+EXPLAIN (COSTS OFF)
+SELECT jt.id, it.data
+FROM join_test jt
+JOIN index_test it ON jt.ref_id = it.num
+WHERE jt.id BETWEEN 100 AND 200;
+
+ALTER INDEX idx_join VISIBLE;
+ALTER INDEX join_test_pkey VISIBLE;
+SELECT show_index_status('idx_join');
+SELECT show_index_status('join_test_pkey');
+
+-- Test REINDEX CONCURRENTLY
+REINDEX INDEX CONCURRENTLY idx_join;
+SELECT show_index_status('idx_join');
+
+ALTER INDEX idx_join INVISIBLE;
+SELECT show_index_status('idx_join');
+REINDEX INDEX CONCURRENTLY idx_join;
+SELECT show_index_status('idx_join');
+
+SELECT pg_get_indexdef('idx_join'::regclass);
+ALTER INDEX idx_join VISIBLE;
+SELECT pg_get_indexdef('idx_join'::regclass);
+
+-- Test index visibility with indcheckxmin being true
+
+CREATE TABLE indcheckxmin_test(id int PRIMARY KEY);
+INSERT INTO indcheckxmin_test VALUES (1), (2), (3);
+CREATE INDEX CONCURRENTLY idx_checkxmin ON indcheckxmin_test(id);
+BEGIN;
+-- Simulate indcheckxmin being true
+UPDATE pg_index SET indcheckxmin = true WHERE indexrelid = 'idx_checkxmin'::regclass;
+ALTER INDEX idx_checkxmin INVISIBLE;  -- expect fail
+ROLLBACK;
+
+-- Test prepared statements with index visibility
+CREATE TABLE prep_idx_test (id int, data text);
+CREATE INDEX prep_idx1 ON prep_idx_test(data);
+INSERT INTO prep_idx_test SELECT g, 'data ' || g FROM generate_series(1,100) g;
+
+-- Test with visible index
+PREPARE idx_plan AS SELECT * FROM prep_idx_test WHERE data = $1;
+EXPLAIN (COSTS OFF) EXECUTE idx_plan('data 1');
+EXECUTE idx_plan('data 1');
+
+-- Test with invisible index
+ALTER INDEX prep_idx1 INVISIBLE;
+EXPLAIN (COSTS OFF) EXECUTE idx_plan('data 1');
+EXECUTE idx_plan('data 1');
+
+-- Test with use_invisible_index
+SET use_invisible_index TO on;
+EXPLAIN (COSTS OFF) EXECUTE idx_plan('data 1');
+EXECUTE idx_plan('data 1');
+SET use_invisible_index TO off;
+-- Assert plan cache is reset and index is not used
+EXPLAIN (COSTS OFF) EXECUTE idx_plan('data 1');
+
+-- Make index visible and test again
+ALTER INDEX prep_idx1 VISIBLE;
+EXPLAIN (COSTS OFF) EXECUTE idx_plan('data 1');
+EXECUTE idx_plan('data 1');
+
+-- Test index visibility with partitioned tables
+CREATE TABLE part_tbl(id int, data text) PARTITION BY RANGE(id);
+CREATE TABLE part1 PARTITION OF part_tbl FOR VALUES FROM (1) TO (100);
+CREATE TABLE part2 PARTITION OF part_tbl FOR VALUES FROM (100) TO (200);
+
+INSERT INTO part_tbl
+SELECT g, 'data ' || g
+FROM generate_series(1, 199) g;
+
+CREATE INDEX idx_part_tbl ON part_tbl(data);
+
+SELECT c.relname, i.indisvisible
+FROM pg_index i
+JOIN pg_class c ON i.indexrelid = c.oid
+WHERE c.relname LIKE 'idx_part_tbl%'
+ORDER BY c.relname;
+
+-- Force use of indexes to avoid flaky test results
+SET enable_seqscan = off;
+
+EXPLAIN (COSTS OFF)
+SELECT * FROM part_tbl WHERE data = 'data 50';
+
+ALTER INDEX idx_part_tbl INVISIBLE;
+
+SELECT c.relname, i.indisvisible
+FROM pg_index i
+JOIN pg_class c ON i.indexrelid = c.oid
+WHERE c.relname LIKE 'idx_part_tbl%'
+ORDER BY c.relname;
+
+-- Check query plan after setting invisible (should use seq scan)
+EXPLAIN (COSTS OFF)
+SELECT * FROM part_tbl WHERE data = 'data 50';
+
+SET use_invisible_index TO on;
+
+EXPLAIN (COSTS OFF)
+SELECT * FROM part_tbl WHERE data = 'data 50';
+
+SET use_invisible_index TO off;
+
+EXPLAIN (COSTS OFF)
+SELECT * FROM part_tbl WHERE data = 'data 50';
+
+ALTER INDEX idx_part_tbl VISIBLE;
+
+SELECT c.relname, i.indisvisible
+FROM pg_index i
+JOIN pg_class c ON i.indexrelid = c.oid
+WHERE c.relname LIKE 'idx_part_tbl%'
+ORDER BY c.relname;
+
+EXPLAIN (COSTS OFF)
+SELECT * FROM part_tbl WHERE data = 'data 50';
+
+SET enable_seqscan = on;
+
+-- Test REINDEX maintains visibility setting
+ALTER INDEX idx_part_tbl INVISIBLE;
+REINDEX INDEX idx_part_tbl;
+
+SELECT c.relname, i.indisvisible
+FROM pg_index i
+JOIN pg_class c ON i.indexrelid = c.oid
+WHERE c.relname LIKE 'idx_part_tbl%'
+ORDER BY c.relname;
+
+-- Clean up
+DROP TABLE index_test;
+DROP TABLE join_test;
+DROP FUNCTION get_data_length;
+DROP FUNCTION show_index_status;
+DROP TABLE indcheckxmin_test CASCADE;
+DEALLOCATE idx_plan;
+DROP TABLE prep_idx_test;
+DROP TABLE part_tbl CASCADE;
+
 -- Failure for unauthorized user
 CREATE ROLE regress_reindexuser NOLOGIN;
 SET SESSION ROLE regress_reindexuser;
-- 
2.39.5 (Apple Git-154)

#67Shayon Mukherjee
shayonj@gmail.com
In reply to: Benoit Lobréau (#61)
Re: Proposal to Enable/Disable Index using ALTER INDEX (with patch)

On Fri, Jan 24, 2025 at 4:03 PM Benoit Lobréau <benoit.lobreau@gmail.com>
wrote:

I did notice something in the command prototype:

+ALTER INDEX [ IF EXISTS ] <replaceable
class="parameter">name</replaceable> VISIBLE
+ALTER INDEX [ IF EXISTS ] <replaceable
class="parameter">name</replaceable> INVISIBLE

it would probably be better as:

+ALTER INDEX [ IF EXISTS ] <replaceable
class="parameter">name</replaceable> {VISIBLE|INVISIBLE}

Thank you for your review, really appreciate it! I have updated with your
feedback in v10 patch [1]/messages/by-id/CANqtF-rs5N4ZepiH9YV1VVi6YNtyFDzDbJabhcZKqh-hNgLmgw@mail.gmail.com

The completion for the INVISIBLE / VISIBLE keyword is missing in psql.

Also updated in v10 patch [1]/messages/by-id/CANqtF-rs5N4ZepiH9YV1VVi6YNtyFDzDbJabhcZKqh-hNgLmgw@mail.gmail.com

Additionally, I tried using the ALTER command on an index that supports
a foreign key. As expected, delete and update operations on the referenced
table became significantly slower. I was wondering if this behavior should
be documented here.

+      Make the specified index invisible. The index will not be used
for queries.
+      This can be useful for testing query performance with and
without specific
+      indexes.

Maybe something like :

The index will not be used for user or system queries (e.g., an index
supporting foreign keys).

I noticed that you mentionned checking pg_stat_user_indexes before using
the query but it might not be enough?

This part of the documentation has gone through some changes, and I have
sensed it's hard to convey the details without complicating or breaking
precedence. By saying "The index will not be used for queries", I (as a
PostgreSQL user) was assuming this would apply to both user and system
queries, and hence the distinction was implicit. However, I don't have a
strong opinion and am happy to make the changes. I am also curious if
anyone else has thoughts on this as well?

[1]: /messages/by-id/CANqtF-rs5N4ZepiH9YV1VVi6YNtyFDzDbJabhcZKqh-hNgLmgw@mail.gmail.com
/messages/by-id/CANqtF-rs5N4ZepiH9YV1VVi6YNtyFDzDbJabhcZKqh-hNgLmgw@mail.gmail.com

Thank you
Shayon

#68Shayon Mukherjee
shayonj@gmail.com
In reply to: Benoit Lobréau (#63)
Re: Proposal to Enable/Disable Index using ALTER INDEX (with patch)

On Fri, Jan 24, 2025 at 8:56 PM Benoit Lobréau <benoit.lobreau@gmail.com>
wrote:

I also noticed that \d on an index doesn't warn about the invisible state
whereas \d on a table does:

Thank you for the review + patch (v9-002) [1]/messages/by-id/CAPE8EZ5G+CZiw=p1Cs7DOZ2MGLa1yTS8Tk=Thzi1F14N2A=1oQ@mail.gmail.com. Your patch looks good to me.
I have not incorporated this in my v10 patch [2]/messages/by-id/CANqtF-rs5N4ZepiH9YV1VVi6YNtyFDzDbJabhcZKqh-hNgLmgw@mail.gmail.com. Mostly to make sure you
are credited and also being new here and not knowing whether or not I
should :) (to help with the reviewing process, etc). Open to suggestions
and feedback.

[1]: /messages/by-id/CAPE8EZ5G+CZiw=p1Cs7DOZ2MGLa1yTS8Tk=Thzi1F14N2A=1oQ@mail.gmail.com
/messages/by-id/CAPE8EZ5G+CZiw=p1Cs7DOZ2MGLa1yTS8Tk=Thzi1F14N2A=1oQ@mail.gmail.com

[2]: /messages/by-id/CANqtF-rs5N4ZepiH9YV1VVi6YNtyFDzDbJabhcZKqh-hNgLmgw@mail.gmail.com
/messages/by-id/CANqtF-rs5N4ZepiH9YV1VVi6YNtyFDzDbJabhcZKqh-hNgLmgw@mail.gmail.com

Thank you
Shayon

#69jian he
jian.universality@gmail.com
In reply to: Shayon Mukherjee (#68)
Re: Proposal to Enable/Disable Index using ALTER INDEX (with patch)

hi.
the following reviews based on
v10-0001-Introduce-the-ability-to-set-index-visibility-us.patch.

in src/test/regress/sql/create_index.sql
seems there are no sql tests for "create index ... invisible"?

<varlistentry>
<term><literal>VISIBLE</literal></term>
<listitem>
<para>
Make the specified index visible. The index will be used for queries.
</para>
</listitem>
</varlistentry>
here it should be
"Make the specified index visible. The index can be used for query planning"
?

Do we need to add GUC use_invisible_index to postgresql.conf.sample?

CREATE TABLE t(id INT PRIMARY KEY, data TEXT,num INT, vector INT[],
range INT4RANGE);
ALTER INDEX t_pkey INVISIBLE;
alter table t alter column id set data type bigint;
\d t

after ALTER TABLE SET DATA TYPE, the "visible" status should not change?
but here it changed.
you may check ATPostAlterTypeParse to make the "visible" status not change.

@@ -3449,6 +3451,7 @@ typedef struct IndexStmt
     bool        if_not_exists;    /* just do nothing if index already
exists? */
     bool        reset_default_tblspc;    /* reset default_tablespace prior to
                                          * executing */
+  bool        isvisible;        /* true if VISIBLE (default), false
if INVISIBLE */
 } IndexStmt;
the indentation level is not right?
+opt_index_visibility:
+            VISIBLE_P                      { $$ = true; }
+            | INVISIBLE_P                   { $$ = false; }
+            | /*EMPTY*/                     { $$ = true; }
+        ;
+
the indentation level seems also not right?
+    createFlags = INDEX_CREATE_SKIP_BUILD | INDEX_CREATE_CONCURRENT;
+    if (indexForm->indisvisible)
+            createFlags |= INDEX_CREATE_VISIBLE;
the indentation level seems also not right?

INVISIBLE, VISIBLE is not special words, in gram.y, you don't need
"VISIBLE_P", "INVISIBLE_P", you can just use "INVISIBLE", "VISIBLE"
?

\d t3
Table "public.t3"
Column | Type | Collation | Nullable | Default
--------+-----------+-----------+----------+---------
id | integer | | not null |
data | text | | |
num | integer | | |
vector | integer[] | | |
range | int4range | | |
a | box | | |
Indexes:
"t3_pkey" PRIMARY KEY, btree (id) INVISIBLE
"grect2ind" gist (a) INVISIBLE
"t3_1" gist (a) INVISIBLE
"t3_2" gin (vector) WITH (fastupdate='on',
gin_pending_list_limit='128') INVISIBLE
"t3_4" spgist (data) INVISIBLE
"t3_6" hash (id) INVISIBLE

pg_dump will dump as
--
-- Name: t3 t3_pkey; Type: CONSTRAINT; Schema: public; Owner: jian
--
ALTER TABLE ONLY public.t3
ADD CONSTRAINT t3_pkey PRIMARY KEY (id);

after dump, restore index (primary key: t3_pkey) INVISIBLE will not be restored.
We need extra work for restoring the INVISIBLE flag for the primary key index.

I am not sure if we need to change index_concurrently_swap or not.
but many other pg_index columns changed.

#70jian he
jian.universality@gmail.com
In reply to: jian he (#69)
1 attachment(s)
Re: Proposal to Enable/Disable Index using ALTER INDEX (with patch)

hi.
....
modules/test_ddl_deparse/test_ddl_deparse.so.p/test_ddl_deparse.c.o -c
../../Desktop/pg_src/src7/postgres/src/test/modules/test_ddl_deparse/test_ddl_deparse.c
../../Desktop/pg_src/src7/postgres/src/test/modules/test_ddl_deparse/test_ddl_deparse.c:
In function ‘get_altertable_subcmdinfo’:
../../Desktop/pg_src/src7/postgres/src/test/modules/test_ddl_deparse/test_ddl_deparse.c:111:17:
error: enumeration value ‘AT_SetIndexVisible’ not handled in switch
[-Werror=switch]
111 | switch (subcmd->subtype)
| ^~~~~~
../../Desktop/pg_src/src7/postgres/src/test/modules/test_ddl_deparse/test_ddl_deparse.c:111:17:
error: enumeration value ‘AT_SetIndexInvisible’ not handled in switch
[-Werror=switch]
cc1: all warnings being treated as errors

so we need to change test_ddl_deparse.c.
The attached patch fixes the indentation and test_ddl_deparse.c issue.
Maybe we can add some tests on src/test/modules/test_ddl_deparse.

Attachments:

v10-0001-minor-indentation-fix.no-cfbotapplication/octet-stream; name=v10-0001-minor-indentation-fix.no-cfbotDownload
From a341f8abf77df8ea9befb278b82c8537a1e4b4f4 Mon Sep 17 00:00:00 2001
From: jian he <jian.universality@gmail.com>
Date: Mon, 3 Feb 2025 10:43:31 +0800
Subject: [PATCH v10 1/1] minor indentation fix

---
 src/backend/catalog/index.c                          | 2 +-
 src/backend/commands/tablecmds.c                     | 4 ++--
 src/backend/parser/gram.y                            | 2 +-
 src/include/catalog/index.h                          | 2 +-
 src/include/nodes/parsenodes.h                       | 6 +++---
 src/test/modules/test_ddl_deparse/test_ddl_deparse.c | 6 ++++++
 6 files changed, 14 insertions(+), 8 deletions(-)

diff --git a/src/backend/catalog/index.c b/src/backend/catalog/index.c
index ef51e6de0b..68aece185e 100644
--- a/src/backend/catalog/index.c
+++ b/src/backend/catalog/index.c
@@ -1455,7 +1455,7 @@ index_concurrently_create_copy(Relation heapRelation, Oid oldIndexId,
 	*/
 	createFlags = INDEX_CREATE_SKIP_BUILD | INDEX_CREATE_CONCURRENT;
 	if (indexForm->indisvisible)
-			createFlags |= INDEX_CREATE_VISIBLE;
+		createFlags |= INDEX_CREATE_VISIBLE;
 
 	/*
 	 * Now create the new index.
diff --git a/src/backend/commands/tablecmds.c b/src/backend/commands/tablecmds.c
index 254144e5cb..ba70fde178 100644
--- a/src/backend/commands/tablecmds.c
+++ b/src/backend/commands/tablecmds.c
@@ -21096,9 +21096,9 @@ ATExecSetIndexVisibility(Relation rel, bool visible)
 	indexForm = (Form_pg_index) GETSTRUCT(indexTuple);
 	if (indexForm->indcheckxmin)
 		ereport(ERROR,
-				(errcode(ERRCODE_OBJECT_NOT_IN_PREREQUISITE_STATE),
+				errcode(ERRCODE_OBJECT_NOT_IN_PREREQUISITE_STATE),
 				errmsg("cannot update index visibility while indcheckxmin is true"),
-				errhint("Wait for all transactions that might see inconsistent HOT chains to complete")));
+				errhint("Wait for all transactions that might see inconsistent HOT chains to complete"));
 
 	if (indexForm->indisvisible != visible)
 	{
diff --git a/src/backend/parser/gram.y b/src/backend/parser/gram.y
index 475ee26036..d4dfb9ca52 100644
--- a/src/backend/parser/gram.y
+++ b/src/backend/parser/gram.y
@@ -8266,7 +8266,7 @@ opt_unique:
 		;
 
 opt_index_visibility:
-			VISIBLE_P                      { $$ = true; }
+			VISIBLE_P                       { $$ = true; }
 			| INVISIBLE_P                   { $$ = false; }
 			| /*EMPTY*/                 	{ $$ = true; }
 		;
diff --git a/src/include/catalog/index.h b/src/include/catalog/index.h
index ff0f9916de..7edde3078f 100644
--- a/src/include/catalog/index.h
+++ b/src/include/catalog/index.h
@@ -65,7 +65,7 @@ extern void index_check_primary_key(Relation heapRel,
 #define	INDEX_CREATE_IF_NOT_EXISTS			(1 << 4)
 #define	INDEX_CREATE_PARTITIONED			(1 << 5)
 #define INDEX_CREATE_INVALID				(1 << 6)
-#define INDEX_CREATE_VISIBLE        (1 << 7)
+#define INDEX_CREATE_VISIBLE        		(1 << 7)
 
 extern Oid	index_create(Relation heapRelation,
 						 const char *indexRelationName,
diff --git a/src/include/nodes/parsenodes.h b/src/include/nodes/parsenodes.h
index e9553d0f24..5c43cf074f 100644
--- a/src/include/nodes/parsenodes.h
+++ b/src/include/nodes/parsenodes.h
@@ -2467,8 +2467,8 @@ typedef enum AlterTableType
 	AT_SetIdentity,				/* SET identity column options */
 	AT_DropIdentity,			/* DROP IDENTITY */
 	AT_ReAddStatistics,			/* internal to commands/tablecmds.c */
-	AT_SetIndexVisible,					/* Set INDEX visible */
-	AT_SetIndexInvisible,				/* Set INDEX invisible */
+	AT_SetIndexVisible,			/* Set INDEX visible */
+	AT_SetIndexInvisible,		/* Set INDEX invisible */
 } AlterTableType;
 
 typedef struct ReplicaIdentityStmt
@@ -3451,7 +3451,7 @@ typedef struct IndexStmt
 	bool		if_not_exists;	/* just do nothing if index already exists? */
 	bool		reset_default_tblspc;	/* reset default_tablespace prior to
 										 * executing */
-  bool		isvisible;		/* true if VISIBLE (default), false if INVISIBLE */
+	bool		isvisible;		/* true if VISIBLE (default), false if INVISIBLE */
 } IndexStmt;
 
 /* ----------------------
diff --git a/src/test/modules/test_ddl_deparse/test_ddl_deparse.c b/src/test/modules/test_ddl_deparse/test_ddl_deparse.c
index 193669f2bc..8d7c7e5894 100644
--- a/src/test/modules/test_ddl_deparse/test_ddl_deparse.c
+++ b/src/test/modules/test_ddl_deparse/test_ddl_deparse.c
@@ -308,6 +308,12 @@ get_altertable_subcmdinfo(PG_FUNCTION_ARGS)
 			case AT_ReAddStatistics:
 				strtype = "(re) ADD STATS";
 				break;
+			case AT_SetIndexVisible:
+				strtype = "SET VISIBLE";
+				break;
+			case AT_SetIndexInvisible:
+				strtype = "SET INVISIBLE";
+				break;
 		}
 
 		if (subcmd->recurse)
-- 
2.34.1

#71Shayon Mukherjee
shayonj@gmail.com
In reply to: jian he (#69)
1 attachment(s)
Re: Proposal to Enable/Disable Index using ALTER INDEX (with patch)

On Sun, Feb 2, 2025 at 3:11 PM jian he <jian.universality@gmail.com> wrote:

hi.
the following reviews based on
v10-0001-Introduce-the-ability-to-set-index-visibility-us.patch.

Thank you for the amazing review!!

in src/test/regress/sql/create_index.sql
seems there are no sql tests for "create index ... invisible"?

Good call, added in v11 patch (attached)

"Make the specified index visible. The index can be used for query
planning"
?

Done in v11 patch.

Do we need to add GUC use_invisible_index to postgresql.conf.sample?

I wasn't sure at first, hence opted for GUC_NOT_IN_SAMPLE when introducing
the GUC. I have added the new GUC in postgresql.conf.sample as part of the
v11 patch.

CREATE TABLE t(id INT PRIMARY KEY, data TEXT,num INT, vector INT[],
range INT4RANGE);
ALTER INDEX t_pkey INVISIBLE;
alter table t alter column id set data type bigint;
\d t

after ALTER TABLE SET DATA TYPE, the "visible" status should not change?
but here it changed.
you may check ATPostAlterTypeParse to make the "visible" status not change.

Thank you! I was relying on the existing specs to guide me on cases like
this. That said - now I have fixed this in the v11 patch and also added
regression specs for the same (future proofing and all).

....
+    createFlags = INDEX_CREATE_SKIP_BUILD | INDEX_CREATE_CONCURRENT;
+    if (indexForm->indisvisible)
+            createFlags |= INDEX_CREATE_VISIBLE;
the indentation level seems also not right?

Thank you. I have struggled with indentation in the project a bit. I have
gone ahead and fixed these, but I would love to know how do folks generally
solve this and if they use any linting tools? I just use VScode, so my
tooling may not be right for local dev.

INVISIBLE, VISIBLE is not special words, in gram.y, you don't need
"VISIBLE_P", "INVISIBLE_P", you can just use "INVISIBLE", "VISIBLE"
?

Got it, thank you and updated!

....

pg_dump will dump as
--
-- Name: t3 t3_pkey; Type: CONSTRAINT; Schema: public; Owner: jian
--
ALTER TABLE ONLY public.t3
ADD CONSTRAINT t3_pkey PRIMARY KEY (id);

after dump, restore index (primary key: t3_pkey) INVISIBLE will not be
restored.
We need extra work for restoring the INVISIBLE flag for the primary key
index.

Great catch! I am learning that handling of primary keys and constraint +
indexes behave slightly differently in terms of logic across the codebase.
I have updated the v11 patch with the fixes to ensure that pg_dump will
respect the index visibility status on primary keys and also followed up
with specs in 002_pg_dump.pl as a way to future proof the behavior. It was
nice to learn more on how testing inside the .pl specs work as well.

I am not sure if we need to change index_concurrently_swap or not.
but many other pg_index columns changed.

My apologies, but I didn't fully follow this feedback. There are some specs
in create_index.sql for REINDEX behavior when index visibility and I didn't
notice any change in behavior in terms of query planning or the columns in
pg_index. The only change I noticed was the rel id, which makes sense given
the behavior of REINDEX. Once I understand the issue more, happy to follow
up with fixes/specs accordingly.

Few additional notes

- The v11 patch now shows the index invisibility status when you do \d
index_name. h/t to Benoit Lobréau for the patch [1]/messages/by-id/CAPE8EZ5G+CZiw=p1Cs7DOZ2MGLa1yTS8Tk=Thzi1F14N2A=1oQ@mail.gmail.com
- The v11 patch also updated test_ddl_deparse.c as mentioned in [2]/messages/by-id/CACJufxHROE2pDRYecnts9u12K-2R3AGhFADEw_C-GNiRWKZ6ig@mail.gmail.com and
also brings in new specs in
src/test/modules/test_ddl_deparse/expected/alter_index.out as a follow up.
- I found it interesting that this wasn't caught in specs in CI or
anywhere else and I think it is dependent on the clang flags (?). Anyways,
sharing for posterity. For now there is spec coverage for future cases in
v11 patch.

[1]: /messages/by-id/CAPE8EZ5G+CZiw=p1Cs7DOZ2MGLa1yTS8Tk=Thzi1F14N2A=1oQ@mail.gmail.com
/messages/by-id/CAPE8EZ5G+CZiw=p1Cs7DOZ2MGLa1yTS8Tk=Thzi1F14N2A=1oQ@mail.gmail.com
[2]: /messages/by-id/CACJufxHROE2pDRYecnts9u12K-2R3AGhFADEw_C-GNiRWKZ6ig@mail.gmail.com
/messages/by-id/CACJufxHROE2pDRYecnts9u12K-2R3AGhFADEw_C-GNiRWKZ6ig@mail.gmail.com

Attachments:

v11-0001-Introduce-the-ability-to-set-index-visibility-us.patchapplication/octet-stream; name=v11-0001-Introduce-the-ability-to-set-index-visibility-us.patchDownload
From 70b1b6180e6833089345515fafbab7736df1f989 Mon Sep 17 00:00:00 2001
From: Shayon Mukherjee <shayonj@gmail.com>
Date: Sun, 12 Jan 2025 14:34:48 -0500
Subject: [PATCH v11] Introduce the ability to set index visibility using ALTER
 INDEX

This patch introduces index visibility control using ALTER INDEX and CREATE INDEX
commands.

Original motivation for the problem and proposal for a patch
can be found at [1].

This patch passes all the existing specs and the newly added regression tests. The patch
is ready for review and test. It compiles, so the patch can be applied for testing as well.

Note: The patch has gone through a few iterations. Earlier versions of the patch had the ENABLE/DISABLE grammar.
The current version has the VISIBLE/INVISIBLE grammar. So, you will the local variable names using the new grammar accordingly.

Implementation details:

- New Grammar:
  * ALTER INDEX ... VISIBLE/INVISIBLE
  * CREATE INDEX ... INVISIBLE

- Default state is visible. Indexes are only invisible when explicitly
  instructed via CREATE INDEX ... INVISIBLE or ALTER INDEX ... INVISIBLE.

- Primary Key and Unique constraint indexes are always visible. The
  VISIBLE/INVISIBLE grammar is supported for these types of indexes and they can
  be made invisible via ALTER INDEX ... INVISIBLE.

- ALTER INDEX ... VISIBLE/INVISIBLE performs update on the relevant row in pg_index
  catalog

- pg_get_indexdef() supports the new functionality and grammar. This change is
  reflected in \d output for tables and pg_dump. We show the INVISIBLE syntax accordingly.

- Added force_invisible_index GUC parameter that forces the planner to use invisible
  indexes. This is useful for testing and validating index behavior without changing
  their visibility state. Based on feedback from Sami S [2]

- Updated create_index.sql regression test to cover the new grammar and verify
  that invisible indexes are not used in queries. The test covers:

  - Basic single-column and multi-column indexes
  - Partial indexes
  - Expression indexes
  - Join indexes
  - GIN and GiST indexes
  - Covering indexes
  - Range indexes
  - Unique indexes and constraints

- Adds a new indisvisible attribute to the IndexOptInfo structure.

- Modifies get_relation_info in plancat.c to skip invisible indexes entirely, thus reducing the number of places we need to check if an index is invisible or not. Inspired by the conversations start at [3].
  - I chose to modify the logic within get_relation_info as compared to, say, reducing the cost to make the planner not consider an index during planning, mostly to keep the number of changes being introduced to a minimum and also the logic itself being self-contained and easier to understand perhaps (?).

- No changes are made to stop the index from getting maintained. This way we ensure no
  data loss or corruption when index is made visible again.

- TOAST indexes are supported and visible by default as well.

- REINDEX CONCURRENTLY is supported as well and existing state of pg_index.indisvisible
  is carried over accordingly.

- See the changes in create_index.sql to get an idea of the grammar and sql statements.

- See the changes in create_index.out to get an idea of the catalogue states and EXPLAIN
  output to see when an index is getting used or isn't (when invisible).

- Incorporated DavidR's feedback from [4] around documentation and also you will see that by skipping invisible indexes entirely from get_relation_info in plancat.c (as mentioned above), we address the other mentioned issues as well.

- Lastly, protects against the case where indcheckxmin is true by raising ERRCODE_OBJECT_NOT_IN_PREREQUISITE_STATE.

Looking forward to any and all feedback on this patch, including but not limited to code quality, tests, fundamental logic.

[1] https://www.postgresql.org/message-id/CANqtF-oXKe0M%3D0QOih6H%2BsZRjE2BWAbkW_1%2B9nMEAMLxUJg5jA%40mail.gmail.com
[2] https://www.postgresql.org/message-id/CAA5RZ0udzydObMDi65C59-oq54B9ZmjSZ1wVH3h%2Bv4XiVm6QDA%40mail.gmail.com
[3] https://www.postgresql.org/message-id/3465209.1727202064%40sss.pgh.pa.us
[4] https://www.postgresql.org/message-id/CAApHDvpUNu%3DiVcdJ74sypvgeaCF%2Btfpyb8VRhZaF7DTd1xVr7g%40mail.gmail.com
---
 doc/src/sgml/catalogs.sgml                    |  11 +
 doc/src/sgml/config.sgml                      |  16 +
 doc/src/sgml/ref/alter_index.sgml             |  38 +
 doc/src/sgml/ref/create_index.sgml            |  29 +
 src/backend/bootstrap/bootparse.y             |   2 +
 src/backend/catalog/index.c                   |  31 +-
 src/backend/catalog/toasting.c                |   2 +-
 src/backend/commands/indexcmds.c              |   4 +
 src/backend/commands/tablecmds.c              |  92 +-
 src/backend/optimizer/util/plancat.c          |  31 +-
 src/backend/parser/gram.y                     |  56 +-
 src/backend/parser/parse_utilcmd.c            |   3 +
 src/backend/utils/adt/ruleutils.c             |   4 +
 src/backend/utils/cache/relcache.c            |   1 +
 src/backend/utils/misc/guc_tables.c           |  11 +
 src/backend/utils/misc/postgresql.conf.sample |   1 +
 src/bin/pg_dump/pg_dump.c                     |  20 +-
 src/bin/pg_dump/pg_dump.h                     |   2 +
 src/bin/pg_dump/t/002_pg_dump.pl              |  29 +
 src/bin/psql/describe.c                       |  15 +-
 src/bin/psql/tab-complete.in.c                |   3 +-
 src/include/catalog/index.h                   |   2 +-
 src/include/catalog/pg_index.h                |   1 +
 src/include/nodes/parsenodes.h                |   3 +
 src/include/optimizer/optimizer.h             |   5 +
 src/include/parser/kwlist.h                   |   2 +
 src/include/utils/guc_hooks.h                 |   1 +
 src/test/modules/test_ddl_deparse/Makefile    |   3 +-
 .../test_ddl_deparse/expected/alter_index.out |  29 +
 .../test_ddl_deparse/sql/alter_index.sql      |  18 +
 .../test_ddl_deparse/test_ddl_deparse.c       |   6 +
 src/test/regress/expected/create_index.out    | 795 ++++++++++++++++++
 src/test/regress/sql/create_index.sql         | 321 +++++++
 33 files changed, 1561 insertions(+), 26 deletions(-)
 create mode 100644 src/test/modules/test_ddl_deparse/expected/alter_index.out
 create mode 100644 src/test/modules/test_ddl_deparse/sql/alter_index.sql

diff --git a/doc/src/sgml/catalogs.sgml b/doc/src/sgml/catalogs.sgml
index 088fb175cc..8b0019d0e6 100644
--- a/doc/src/sgml/catalogs.sgml
+++ b/doc/src/sgml/catalogs.sgml
@@ -4595,6 +4595,17 @@ SCRAM-SHA-256$<replaceable>&lt;iteration count&gt;</replaceable>:<replaceable>&l
        partial index.
       </para></entry>
      </row>
+
+     <row>
+      <entry role="catalog_table_entry"><para role="column_definition">
+       <structfield>indisvisible</structfield> <type>bool</type>
+      </para>
+      <para>
+       If true, the index is currently visible to the planner and may be used for queries.
+       If false, the index is invisible and may not be used for queries,
+       but is still updated when the table is modified. Default is true.
+      </para></entry>
+     </row>
     </tbody>
    </tgroup>
   </table>
diff --git a/doc/src/sgml/config.sgml b/doc/src/sgml/config.sgml
index a782f10998..873fae9a93 100644
--- a/doc/src/sgml/config.sgml
+++ b/doc/src/sgml/config.sgml
@@ -5589,6 +5589,22 @@ ANY <replaceable class="parameter">num_sync</replaceable> ( <replaceable class="
       </listitem>
      </varlistentry>
 
+     <varlistentry id="guc-force-invisible-index" xreflabel="use_invisible_index">
+      <term><varname>use_invisible_index</varname> (<type>boolean</type>)
+      <indexterm>
+       <primary><varname>use_invisible_index</varname> configuration parameter</primary>
+      </indexterm>
+      </term>
+      <listitem>
+       <para>
+        Forces the query planner to consider indexes that have been marked as invisible using
+        <command>ALTER INDEX ... INVISIBLE</command>. This parameter is useful for selective
+        use of invisible indexes in specific application contexts. The default
+        is <literal>off</literal>.
+       </para>
+      </listitem>
+     </varlistentry>
+
      </variablelist>
      </sect2>
      <sect2 id="runtime-config-query-constants">
diff --git a/doc/src/sgml/ref/alter_index.sgml b/doc/src/sgml/ref/alter_index.sgml
index 1d42d05d85..d26e7761c1 100644
--- a/doc/src/sgml/ref/alter_index.sgml
+++ b/doc/src/sgml/ref/alter_index.sgml
@@ -31,6 +31,7 @@ ALTER INDEX [ IF EXISTS ] <replaceable class="parameter">name</replaceable> ALTE
     SET STATISTICS <replaceable class="parameter">integer</replaceable>
 ALTER INDEX ALL IN TABLESPACE <replaceable class="parameter">name</replaceable> [ OWNED BY <replaceable class="parameter">role_name</replaceable> [, ... ] ]
     SET TABLESPACE <replaceable class="parameter">new_tablespace</replaceable> [ NOWAIT ]
+ALTER INDEX [ IF EXISTS ] <replaceable class="parameter">name</replaceable> { VISIBLE | INVISIBLE }
 </synopsis>
  </refsynopsisdiv>
 
@@ -159,6 +160,29 @@ ALTER INDEX ALL IN TABLESPACE <replaceable class="parameter">name</replaceable>
     </listitem>
    </varlistentry>
 
+   <varlistentry>
+    <term><literal>VISIBLE</literal></term>
+    <listitem>
+     <para>
+      Make the specified index visible. The index will be used for query planning.
+     </para>
+    </listitem>
+   </varlistentry>
+
+   <varlistentry>
+    <term><literal>INVISIBLE</literal></term>
+    <listitem>
+     <para>
+      Make the specified index invisible. The index will not be used for queries.
+      This can be useful for testing query performance with and without specific
+      indexes. If performance degrades after making an index invisible, it can be easily
+      be made visible using <literal>VISIBLE</literal>. Before making an index invisible, it's recommended
+      to check <structname>pg_stat_user_indexes</structname>.<structfield>idx_scan</structfield>
+      to identify potentially unused indexes.
+     </para>
+    </listitem>
+   </varlistentry>
+
   </variablelist>
   </para>
 
@@ -301,6 +325,20 @@ CREATE INDEX coord_idx ON measured (x, y, (z + t));
 ALTER INDEX coord_idx ALTER COLUMN 3 SET STATISTICS 1000;
 </programlisting></para>
 
+  <para>
+   To make an index visible:
+<programlisting>
+ALTER INDEX idx_name VISIBLE;
+</programlisting>
+  </para>
+
+  <para>
+   To make an index invisible:
+<programlisting>
+ALTER INDEX idx_name INVISIBLE;
+</programlisting>
+  </para>
+
  </refsect1>
 
  <refsect1>
diff --git a/doc/src/sgml/ref/create_index.sgml b/doc/src/sgml/ref/create_index.sgml
index 208389e800..90d7d90a2b 100644
--- a/doc/src/sgml/ref/create_index.sgml
+++ b/doc/src/sgml/ref/create_index.sgml
@@ -28,6 +28,7 @@ CREATE [ UNIQUE ] INDEX [ CONCURRENTLY ] [ [ IF NOT EXISTS ] <replaceable class=
     [ WITH ( <replaceable class="parameter">storage_parameter</replaceable> [= <replaceable class="parameter">value</replaceable>] [, ... ] ) ]
     [ TABLESPACE <replaceable class="parameter">tablespace_name</replaceable> ]
     [ WHERE <replaceable class="parameter">predicate</replaceable> ]
+    [ INVISIBLE ]
 </synopsis>
  </refsynopsisdiv>
 
@@ -380,6 +381,19 @@ CREATE [ UNIQUE ] INDEX [ CONCURRENTLY ] [ [ IF NOT EXISTS ] <replaceable class=
       </listitem>
      </varlistentry>
 
+    <varlistentry>
+      <term><literal>INVISIBLE</literal></term>
+      <listitem>
+       <para>
+        Creates the index in an invisible state (default visible). An invisible index is
+        not used by the query planner for queries, but it is still maintained
+        when the underlying table data changes. This can be useful when you want to create
+        an index without immediately impacting query planning, allowing you to make it
+        visible later at a more convenient time. The index can be made visible later
+        using <command>ALTER INDEX ... VISIBLE</command>.
+       </para>
+      </listitem>
+     </varlistentry>
     </variablelist>
 
   <refsect2 id="sql-createindex-storage-parameters" xreflabel="Index Storage Parameters">
@@ -701,6 +715,14 @@ Indexes:
     partitioned index is a metadata only operation.
    </para>
 
+  <para>
+   When creating an index with the <literal>INVISIBLE</literal> option, the index
+   will be created but not used for query planning. This can be useful for
+   preparing an index in advance of its use, or for testing purposes. The index
+   will still be maintained as the table is modified, so it can be made visible
+   later without needing to be rebuilt. By default all new indexes are visible.
+  </para>
+
   </refsect2>
  </refsect1>
 
@@ -980,6 +1002,13 @@ SELECT * FROM points
 CREATE INDEX CONCURRENTLY sales_quantity_index ON sales_table (quantity);
 </programlisting></para>
 
+  <para>
+   To create an index on the table <literal>test_table</literal> with the default
+   name, but have it initially invisible:
+<programlisting>
+CREATE INDEX ON test_table (col1) INVISIBLE;
+</programlisting>
+  </para>
  </refsect1>
 
  <refsect1>
diff --git a/src/backend/bootstrap/bootparse.y b/src/backend/bootstrap/bootparse.y
index 9833f52c1b..ea21511a20 100644
--- a/src/backend/bootstrap/bootparse.y
+++ b/src/backend/bootstrap/bootparse.y
@@ -303,6 +303,7 @@ Boot_DeclareIndexStmt:
 					stmt->concurrent = false;
 					stmt->if_not_exists = false;
 					stmt->reset_default_tblspc = false;
+					stmt->isvisible = true;
 
 					/* locks and races need not concern us in bootstrap mode */
 					relationId = RangeVarGetRelid(stmt->relation, NoLock,
@@ -356,6 +357,7 @@ Boot_DeclareUniqueIndexStmt:
 					stmt->concurrent = false;
 					stmt->if_not_exists = false;
 					stmt->reset_default_tblspc = false;
+					stmt->isvisible = true;
 
 					/* locks and races need not concern us in bootstrap mode */
 					relationId = RangeVarGetRelid(stmt->relation, NoLock,
diff --git a/src/backend/catalog/index.c b/src/backend/catalog/index.c
index 7377912b41..68aece185e 100644
--- a/src/backend/catalog/index.c
+++ b/src/backend/catalog/index.c
@@ -118,7 +118,8 @@ static void UpdateIndexRelation(Oid indexoid, Oid heapoid,
 								bool isexclusion,
 								bool immediate,
 								bool isvalid,
-								bool isready);
+								bool isready,
+								bool isvisible);
 static void index_update_stats(Relation rel,
 							   bool hasindex,
 							   double reltuples);
@@ -570,7 +571,8 @@ UpdateIndexRelation(Oid indexoid,
 					bool isexclusion,
 					bool immediate,
 					bool isvalid,
-					bool isready)
+					bool isready,
+					bool isvisible)
 {
 	int2vector *indkey;
 	oidvector  *indcollation;
@@ -648,6 +650,7 @@ UpdateIndexRelation(Oid indexoid,
 	values[Anum_pg_index_indisready - 1] = BoolGetDatum(isready);
 	values[Anum_pg_index_indislive - 1] = BoolGetDatum(true);
 	values[Anum_pg_index_indisreplident - 1] = BoolGetDatum(false);
+	values[Anum_pg_index_indisvisible - 1] = BoolGetDatum(isvisible);
 	values[Anum_pg_index_indkey - 1] = PointerGetDatum(indkey);
 	values[Anum_pg_index_indcollation - 1] = PointerGetDatum(indcollation);
 	values[Anum_pg_index_indclass - 1] = PointerGetDatum(indclass);
@@ -713,6 +716,8 @@ UpdateIndexRelation(Oid indexoid,
  *			already exists.
  *		INDEX_CREATE_PARTITIONED:
  *			create a partitioned index (table must be partitioned)
+ *		INDEX_CREATE_VISIBLE:
+ *			create the index as visible to query planner
  * constr_flags: flags passed to index_constraint_create
  *		(only if INDEX_CREATE_ADD_CONSTRAINT is set)
  * allow_system_table_mods: allow table to be a system catalog
@@ -758,6 +763,7 @@ index_create(Relation heapRelation,
 	bool		invalid = (flags & INDEX_CREATE_INVALID) != 0;
 	bool		concurrent = (flags & INDEX_CREATE_CONCURRENT) != 0;
 	bool		partitioned = (flags & INDEX_CREATE_PARTITIONED) != 0;
+	bool 		isvisible  = (flags & INDEX_CREATE_VISIBLE) != 0;
 	char		relkind;
 	TransactionId relfrozenxid;
 	MultiXactId relminmxid;
@@ -1041,13 +1047,15 @@ index_create(Relation heapRelation,
 	 *	  (Or, could define a rule to maintain the predicate) --Nels, Feb '92
 	 * ----------------
 	 */
+
 	UpdateIndexRelation(indexRelationId, heapRelationId, parentIndexRelid,
 						indexInfo,
 						collationIds, opclassIds, coloptions,
 						isprimary, is_exclusion,
 						(constr_flags & INDEX_CONSTR_CREATE_DEFERRABLE) == 0,
 						!concurrent && !invalid,
-						!concurrent);
+						!concurrent,
+						isvisible);
 
 	/*
 	 * Register relcache invalidation on the indexes' heap relation, to
@@ -1316,6 +1324,8 @@ index_concurrently_create_copy(Relation heapRelation, Oid oldIndexId,
 	List	   *indexColNames = NIL;
 	List	   *indexExprs = NIL;
 	List	   *indexPreds = NIL;
+	Form_pg_index indexForm;
+	bits16 	 createFlags;
 
 	indexRelation = index_open(oldIndexId, RowExclusiveLock);
 
@@ -1343,6 +1353,9 @@ index_concurrently_create_copy(Relation heapRelation, Oid oldIndexId,
 											Anum_pg_index_indoption);
 	indcoloptions = (int2vector *) DatumGetPointer(colOptionDatum);
 
+	/* Get the visibility state of the original index */
+	indexForm = (Form_pg_index) GETSTRUCT(indexTuple);
+
 	/* Fetch reloptions of index if any */
 	classTuple = SearchSysCache1(RELOID, ObjectIdGetDatum(oldIndexId));
 	if (!HeapTupleIsValid(classTuple))
@@ -1434,6 +1447,16 @@ index_concurrently_create_copy(Relation heapRelation, Oid oldIndexId,
 		stattargets[i].isnull = isnull;
 	}
 
+	/*
+	* Determine the create flags for the new index.
+	* We always use SKIP_BUILD and CONCURRENT for concurrent reindexing.
+	* If the original index was visible, we also set the VISIBLE flag
+	* to maintain the same state in the new index.
+	*/
+	createFlags = INDEX_CREATE_SKIP_BUILD | INDEX_CREATE_CONCURRENT;
+	if (indexForm->indisvisible)
+		createFlags |= INDEX_CREATE_VISIBLE;
+
 	/*
 	 * Now create the new index.
 	 *
@@ -1457,7 +1480,7 @@ index_concurrently_create_copy(Relation heapRelation, Oid oldIndexId,
 							  indcoloptions->values,
 							  stattargets,
 							  reloptionsDatum,
-							  INDEX_CREATE_SKIP_BUILD | INDEX_CREATE_CONCURRENT,
+							  createFlags,
 							  0,
 							  true, /* allow table to be a system catalog? */
 							  false,	/* is_internal? */
diff --git a/src/backend/catalog/toasting.c b/src/backend/catalog/toasting.c
index 874a8fc89a..7721d16fd3 100644
--- a/src/backend/catalog/toasting.c
+++ b/src/backend/catalog/toasting.c
@@ -325,7 +325,7 @@ create_toast_table(Relation rel, Oid toastOid, Oid toastIndexOid,
 				 BTREE_AM_OID,
 				 rel->rd_rel->reltablespace,
 				 collationIds, opclassIds, NULL, coloptions, NULL, (Datum) 0,
-				 INDEX_CREATE_IS_PRIMARY, 0, true, true, NULL);
+				 INDEX_CREATE_IS_PRIMARY | INDEX_CREATE_VISIBLE, 0, true, true, NULL);
 
 	table_close(toast_rel, NoLock);
 
diff --git a/src/backend/commands/indexcmds.c b/src/backend/commands/indexcmds.c
index 5b1753d468..eb878a56d7 100644
--- a/src/backend/commands/indexcmds.c
+++ b/src/backend/commands/indexcmds.c
@@ -1197,6 +1197,10 @@ DefineIndex(Oid tableId,
 		flags |= INDEX_CREATE_PARTITIONED;
 	if (stmt->primary)
 		flags |= INDEX_CREATE_IS_PRIMARY;
+   if (stmt->isvisible)
+		flags |= INDEX_CREATE_VISIBLE;
+   else
+		flags &= ~INDEX_CREATE_VISIBLE;
 
 	/*
 	 * If the table is partitioned, and recursion was declined but partitions
diff --git a/src/backend/commands/tablecmds.c b/src/backend/commands/tablecmds.c
index 18f64db6e3..d4f4cf7d22 100644
--- a/src/backend/commands/tablecmds.c
+++ b/src/backend/commands/tablecmds.c
@@ -700,7 +700,8 @@ static List *GetParentedForeignKeyRefs(Relation partition);
 static void ATDetachCheckNoForeignKeyRefs(Relation partition);
 static char GetAttributeCompression(Oid atttypid, const char *compression);
 static char GetAttributeStorage(Oid atttypid, const char *storagemode);
-
+static void ATExecSetIndexVisibility(Relation rel, bool visible);
+static bool GetIndexVisibility(Oid indexOid);
 
 /* ----------------------------------------------------------------
  *		DefineRelation
@@ -4789,6 +4790,11 @@ AlterTableGetLockLevel(List *cmds)
 				cmd_lockmode = ShareUpdateExclusiveLock;
 				break;
 
+			case AT_SetIndexVisible:
+			case AT_SetIndexInvisible:
+				cmd_lockmode = ShareUpdateExclusiveLock;
+				break;
+
 			default:			/* oops */
 				elog(ERROR, "unrecognized alter table type: %d",
 					 (int) cmd->subtype);
@@ -5222,6 +5228,13 @@ ATPrepCmd(List **wqueue, Relation rel, AlterTableCmd *cmd,
 			/* No command-specific prep needed */
 			pass = AT_PASS_MISC;
 			break;
+		case AT_SetIndexVisible:
+		case AT_SetIndexInvisible:
+			ATSimplePermissions(cmd->subtype, rel, ATT_INDEX | ATT_PARTITIONED_INDEX);
+			ATSimpleRecursion(wqueue, rel, cmd, true, lockmode, context);
+			/* No command-specific prep needed */
+			pass = AT_PASS_MISC;
+			break;
 		default:				/* oops */
 			elog(ERROR, "unrecognized alter table type: %d",
 				 (int) cmd->subtype);
@@ -5616,6 +5629,12 @@ ATExecCmd(List **wqueue, AlteredTableInfo *tab,
 		case AT_DetachPartitionFinalize:
 			address = ATExecDetachPartitionFinalize(rel, ((PartitionCmd *) cmd->def)->name);
 			break;
+		case AT_SetIndexVisible:
+				ATExecSetIndexVisibility(rel, true);
+				break;
+		case AT_SetIndexInvisible:
+				ATExecSetIndexVisibility(rel, false);
+				break;
 		default:				/* oops */
 			elog(ERROR, "unrecognized alter table type: %d",
 				 (int) cmd->subtype);
@@ -6510,6 +6529,8 @@ alter_table_type_to_string(AlterTableType cmdtype)
 			return "DROP COLUMN";
 		case AT_AddIndex:
 		case AT_ReAddIndex:
+		case AT_SetIndexVisible:
+		case AT_SetIndexInvisible:
 			return NULL;		/* not real grammar */
 		case AT_AddConstraint:
 		case AT_ReAddConstraint:
@@ -14674,6 +14695,8 @@ ATPostAlterTypeParse(Oid oldId, Oid oldRelId, Oid refRelId, char *cmd,
 			stmt->reset_default_tblspc = true;
 			/* keep the index's comment */
 			stmt->idxcomment = GetComment(oldId, RelationRelationId, 0);
+			/* preserve the index's visibility status */
+			stmt->isvisible = GetIndexVisibility(oldId);
 
 			newcmd = makeNode(AlterTableCmd);
 			newcmd->subtype = AT_ReAddIndex;
@@ -14704,6 +14727,8 @@ ATPostAlterTypeParse(Oid oldId, Oid oldRelId, Oid refRelId, char *cmd,
 					indstmt->idxcomment = GetComment(indoid,
 													 RelationRelationId, 0);
 					indstmt->reset_default_tblspc = true;
+					/* preserve the index's visibility status */
+					indstmt->isvisible = GetIndexVisibility(indoid);
 
 					cmd->subtype = AT_ReAddIndex;
 					tab->subcmds[AT_PASS_OLD_INDEX] =
@@ -21034,3 +21059,68 @@ GetAttributeStorage(Oid atttypid, const char *storagemode)
 
 	return cstorage;
 }
+
+/*
+ * ATExecSetIndexVisibility
+ * Performs a catalog update to mark an index as visible or invisible in pg_index.
+ */
+static void
+ATExecSetIndexVisibility(Relation rel, bool visible)
+{
+	Oid			indexOid = RelationGetRelid(rel);
+	Oid			heapOid;
+	Relation	pg_index;
+	Relation	heapRel;
+	HeapTuple	indexTuple;
+	Form_pg_index	indexForm;
+
+	heapOid = IndexGetRelation(indexOid, false);
+	heapRel = table_open(heapOid, AccessShareLock);
+	pg_index = table_open(IndexRelationId, RowExclusiveLock);
+
+	indexTuple = SearchSysCacheCopy1(INDEXRELID, ObjectIdGetDatum(indexOid));
+	if (!HeapTupleIsValid(indexTuple))
+		elog(ERROR, "cache lookup failed for index %u", indexOid);
+
+	indexForm = (Form_pg_index) GETSTRUCT(indexTuple);
+	if (indexForm->indcheckxmin)
+		ereport(ERROR,
+				errcode(ERRCODE_OBJECT_NOT_IN_PREREQUISITE_STATE),
+				errmsg("cannot update index visibility while indcheckxmin is true"),
+				errhint("Wait for all transactions that might see inconsistent HOT chains to complete"));
+
+	if (indexForm->indisvisible != visible)
+	{
+		indexForm->indisvisible = visible;
+		CatalogTupleUpdate(pg_index, &indexTuple->t_self, indexTuple);
+
+		CacheInvalidateRelcache(heapRel);
+		InvokeObjectPostAlterHook(IndexRelationId, indexOid, 0);
+		CommandCounterIncrement();
+	}
+
+	heap_freetuple(indexTuple);
+	table_close(pg_index, RowExclusiveLock);
+	table_close(heapRel, AccessShareLock);
+}
+
+/*
+* Get index visibility status from pg_index
+*/
+static bool
+GetIndexVisibility(Oid indexOid)
+{
+	HeapTuple   indexTuple;
+	Form_pg_index indexForm;
+	bool        isvisible;
+
+	indexTuple = SearchSysCache1(INDEXRELID, ObjectIdGetDatum(indexOid));
+	if (!HeapTupleIsValid(indexTuple))
+		elog(ERROR, "cache lookup failed for index %u", indexOid);
+
+	indexForm = (Form_pg_index) GETSTRUCT(indexTuple);
+	isvisible = indexForm->indisvisible;
+	ReleaseSysCache(indexTuple);
+
+	return isvisible;
+}
diff --git a/src/backend/optimizer/util/plancat.c b/src/backend/optimizer/util/plancat.c
index 71abb01f65..0b0682b505 100644
--- a/src/backend/optimizer/util/plancat.c
+++ b/src/backend/optimizer/util/plancat.c
@@ -47,7 +47,9 @@
 #include "storage/bufmgr.h"
 #include "tcop/tcopprot.h"
 #include "utils/builtins.h"
+#include "utils/guc_hooks.h"
 #include "utils/lsyscache.h"
+#include "utils/plancache.h"
 #include "utils/partcache.h"
 #include "utils/rel.h"
 #include "utils/snapmgr.h"
@@ -55,6 +57,7 @@
 
 /* GUC parameter */
 int			constraint_exclusion = CONSTRAINT_EXCLUSION_PARTITION;
+bool		use_invisible_index = false;
 
 /* Hook for plugins to get control in get_relation_info() */
 get_relation_info_hook_type get_relation_info_hook = NULL;
@@ -254,13 +257,12 @@ get_relation_info(PlannerInfo *root, Oid relationObjectId, bool inhparent,
 			index = indexRelation->rd_index;
 
 			/*
-			 * Ignore invalid indexes, since they can't safely be used for
-			 * queries.  Note that this is OK because the data structure we
-			 * are constructing is only used by the planner --- the executor
-			 * still needs to insert into "invalid" indexes, if they're marked
-			 * indisready.
-			 */
-			if (!index->indisvalid)
+			 * Skip invalid indexes, and invisible indexes unless use_invisible_index
+			 * is set. This is OK because the data structure we are constructing is
+			 * only used by the planner - the executor still needs to insert into
+			 * these indexes if they're marked indisready.
+			*/
+			if (!index->indisvalid || (!index->indisvisible && !use_invisible_index))
 			{
 				index_close(indexRelation, NoLock);
 				continue;
@@ -2610,3 +2612,18 @@ set_baserel_partition_constraint(Relation relation, RelOptInfo *rel)
 		rel->partition_qual = partconstr;
 	}
 }
+
+/*
+ * assign_use_invisible_index
+ * GUC assign_hook for "use_invisible_index" GUC variable.
+ * Resets the plan cache when the value changes.
+ */
+void
+assign_use_invisible_index(bool newval, void *extra)
+{
+	if (use_invisible_index != newval)
+	{
+		use_invisible_index = newval;
+		ResetPlanCache();
+	}
+}
diff --git a/src/backend/parser/gram.y b/src/backend/parser/gram.y
index d7f9c00c40..1f9a79dfd5 100644
--- a/src/backend/parser/gram.y
+++ b/src/backend/parser/gram.y
@@ -324,7 +324,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 %type <ival>	add_drop opt_asc_desc opt_nulls_order
 
 %type <node>	alter_table_cmd alter_type_cmd opt_collate_clause
-	   replica_identity partition_cmd index_partition_cmd
+	   replica_identity partition_cmd index_partition_cmd index_alter_cmd
 %type <list>	alter_table_cmds alter_type_cmds
 %type <list>    alter_identity_column_option_list
 %type <defelt>  alter_identity_column_option
@@ -491,6 +491,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 %type <boolean> opt_unique opt_verbose opt_full
 %type <boolean> opt_freeze opt_analyze opt_default
 %type <defelt>	opt_binary copy_delimiter
+%type <boolean>  opt_index_visibility
 
 %type <boolean> copy_from opt_program
 
@@ -733,7 +734,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 	IDENTITY_P IF_P ILIKE IMMEDIATE IMMUTABLE IMPLICIT_P IMPORT_P IN_P INCLUDE
 	INCLUDING INCREMENT INDENT INDEX INDEXES INHERIT INHERITS INITIALLY INLINE_P
 	INNER_P INOUT INPUT_P INSENSITIVE INSERT INSTEAD INT_P INTEGER
-	INTERSECT INTERVAL INTO INVOKER IS ISNULL ISOLATION
+	INTERSECT INTERVAL INTO INVISIBLE INVOKER IS ISNULL ISOLATION
 
 	JOIN JSON JSON_ARRAY JSON_ARRAYAGG JSON_EXISTS JSON_OBJECT JSON_OBJECTAGG
 	JSON_QUERY JSON_SCALAR JSON_SERIALIZE JSON_TABLE JSON_VALUE
@@ -784,7 +785,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 	UNLISTEN UNLOGGED UNTIL UPDATE USER USING
 
 	VACUUM VALID VALIDATE VALIDATOR VALUE_P VALUES VARCHAR VARIADIC VARYING
-	VERBOSE VERSION_P VIEW VIEWS VOLATILE
+	VERBOSE VERSION_P VIEW VIEWS VISIBLE VOLATILE
 
 	WHEN WHERE WHITESPACE_P WINDOW WITH WITHIN WITHOUT WORK WRAPPER WRITE
 
@@ -2157,6 +2158,24 @@ AlterTableStmt:
 					n->nowait = $13;
 					$$ = (Node *) n;
 				}
+		| ALTER INDEX qualified_name index_alter_cmd
+				{
+					AlterTableStmt *n = makeNode(AlterTableStmt);
+					n->relation = $3;
+					n->cmds = list_make1($4);
+					n->objtype = OBJECT_INDEX;
+					n->missing_ok = false;
+					$$ = (Node *) n;
+				}
+		| ALTER INDEX IF_P EXISTS qualified_name index_alter_cmd
+				{
+					AlterTableStmt *n = makeNode(AlterTableStmt);
+					n->relation = $5;
+					n->cmds = list_make1($6);
+					n->objtype = OBJECT_INDEX;
+					n->missing_ok = true;
+					$$ = (Node *) n;
+				}
 		|	ALTER INDEX qualified_name alter_table_cmds
 				{
 					AlterTableStmt *n = makeNode(AlterTableStmt);
@@ -2382,6 +2401,21 @@ index_partition_cmd:
 				}
 		;
 
+index_alter_cmd:
+		/* ALTER INDEX <name> VISIBLE|INVISIBLE */
+		VISIBLE
+			{
+				AlterTableCmd *n = makeNode(AlterTableCmd);
+				n->subtype = AT_SetIndexVisible;
+				$$ = (Node *) n;
+			}
+		| INVISIBLE
+			{
+				AlterTableCmd *n = makeNode(AlterTableCmd);
+				n->subtype = AT_SetIndexInvisible;
+				$$ = (Node *) n;
+			}
+		;
 alter_table_cmd:
 			/* ALTER TABLE <name> ADD <coldef> */
 			ADD_P columnDef
@@ -8160,7 +8194,7 @@ defacl_privilege_target:
 
 IndexStmt:	CREATE opt_unique INDEX opt_concurrently opt_single_name
 			ON relation_expr access_method_clause '(' index_params ')'
-			opt_include opt_unique_null_treatment opt_reloptions OptTableSpace where_clause
+			opt_include opt_unique_null_treatment opt_reloptions OptTableSpace where_clause opt_index_visibility
 				{
 					IndexStmt *n = makeNode(IndexStmt);
 
@@ -8175,6 +8209,7 @@ IndexStmt:	CREATE opt_unique INDEX opt_concurrently opt_single_name
 					n->options = $14;
 					n->tableSpace = $15;
 					n->whereClause = $16;
+					n->isvisible = $17;
 					n->excludeOpNames = NIL;
 					n->idxcomment = NULL;
 					n->indexOid = InvalidOid;
@@ -8192,7 +8227,7 @@ IndexStmt:	CREATE opt_unique INDEX opt_concurrently opt_single_name
 				}
 			| CREATE opt_unique INDEX opt_concurrently IF_P NOT EXISTS name
 			ON relation_expr access_method_clause '(' index_params ')'
-			opt_include opt_unique_null_treatment opt_reloptions OptTableSpace where_clause
+			opt_include opt_unique_null_treatment opt_reloptions OptTableSpace where_clause opt_index_visibility
 				{
 					IndexStmt *n = makeNode(IndexStmt);
 
@@ -8207,6 +8242,7 @@ IndexStmt:	CREATE opt_unique INDEX opt_concurrently opt_single_name
 					n->options = $17;
 					n->tableSpace = $18;
 					n->whereClause = $19;
+					n->isvisible = $20;
 					n->excludeOpNames = NIL;
 					n->idxcomment = NULL;
 					n->indexOid = InvalidOid;
@@ -8229,6 +8265,12 @@ opt_unique:
 			| /*EMPTY*/								{ $$ = false; }
 		;
 
+opt_index_visibility:
+			VISIBLE                       { $$ = true; }
+			| INVISIBLE                   { $$ = false; }
+			| /*EMPTY*/                 	{ $$ = true; }
+		;
+
 access_method_clause:
 			USING name								{ $$ = $2; }
 			| /*EMPTY*/								{ $$ = DEFAULT_INDEX_TYPE; }
@@ -17806,6 +17848,7 @@ unreserved_keyword:
 			| INSENSITIVE
 			| INSERT
 			| INSTEAD
+			| INVISIBLE
 			| INVOKER
 			| ISOLATION
 			| KEEP
@@ -17990,6 +18033,7 @@ unreserved_keyword:
 			| VERSION_P
 			| VIEW
 			| VIEWS
+			|	VISIBLE
 			| VOLATILE
 			| WHITESPACE_P
 			| WITHIN
@@ -18399,6 +18443,7 @@ bare_label_keyword:
 			| INT_P
 			| INTEGER
 			| INTERVAL
+			| INVISIBLE
 			| INVOKER
 			| IS
 			| ISOLATION
@@ -18645,6 +18690,7 @@ bare_label_keyword:
 			| VERSION_P
 			| VIEW
 			| VIEWS
+			| VISIBLE
 			| VOLATILE
 			| WHEN
 			| WHITESPACE_P
diff --git a/src/backend/parser/parse_utilcmd.c b/src/backend/parser/parse_utilcmd.c
index ca028d2a66..9cd8a65b52 100644
--- a/src/backend/parser/parse_utilcmd.c
+++ b/src/backend/parser/parse_utilcmd.c
@@ -1743,6 +1743,7 @@ generateClonedIndexStmt(RangeVar *heapRel, Relation source_idx,
 	index->concurrent = false;
 	index->if_not_exists = false;
 	index->reset_default_tblspc = false;
+	index->isvisible = idxrec->indisvisible;
 
 	/*
 	 * We don't try to preserve the name of the source index; instead, just
@@ -2364,6 +2365,8 @@ transformIndexConstraint(Constraint *constraint, CreateStmtContext *cxt)
 	index->concurrent = false;
 	index->if_not_exists = false;
 	index->reset_default_tblspc = constraint->reset_default_tblspc;
+	/* Ensure indexes for constraints are created as visible by default */
+	index->isvisible = true;
 
 	/*
 	 * If it's ALTER TABLE ADD CONSTRAINT USING INDEX, look up the index and
diff --git a/src/backend/utils/adt/ruleutils.c b/src/backend/utils/adt/ruleutils.c
index 54dad97555..a46780de87 100644
--- a/src/backend/utils/adt/ruleutils.c
+++ b/src/backend/utils/adt/ruleutils.c
@@ -1562,6 +1562,10 @@ pg_get_indexdef_worker(Oid indexrelid, int colno,
 			else
 				appendStringInfo(&buf, " WHERE %s", str);
 		}
+
+		/* Add INVISIBLE clause if the index is invisible */
+		if (!idxrec->indisvisible)
+				appendStringInfoString(&buf, " INVISIBLE");
 	}
 
 	/* Clean up */
diff --git a/src/backend/utils/cache/relcache.c b/src/backend/utils/cache/relcache.c
index 43219a9629..8c084622eb 100644
--- a/src/backend/utils/cache/relcache.c
+++ b/src/backend/utils/cache/relcache.c
@@ -2311,6 +2311,7 @@ RelationReloadIndexInfo(Relation relation)
 		relation->rd_index->indisready = index->indisready;
 		relation->rd_index->indislive = index->indislive;
 		relation->rd_index->indisreplident = index->indisreplident;
+		relation->rd_index->indisvisible = index->indisvisible;
 
 		/* Copy xmin too, as that is needed to make sense of indcheckxmin */
 		HeapTupleHeaderSetXmin(relation->rd_indextuple->t_data,
diff --git a/src/backend/utils/misc/guc_tables.c b/src/backend/utils/misc/guc_tables.c
index 71448bb4fd..0d8388c35e 100644
--- a/src/backend/utils/misc/guc_tables.c
+++ b/src/backend/utils/misc/guc_tables.c
@@ -2096,6 +2096,17 @@ struct config_bool ConfigureNamesBool[] =
 		NULL, NULL, NULL
 	},
 
+	{
+		{"use_invisible_index", PGC_USERSET, QUERY_TUNING_OTHER,
+			gettext_noop("Forces the planner to consider invisible indexes."),
+			NULL,
+			GUC_EXPLAIN
+		},
+		&use_invisible_index,
+		false,
+		NULL, assign_use_invisible_index, NULL
+	},
+
 	/* End-of-list marker */
 	{
 		{NULL, 0, 0, NULL, NULL}, NULL, false, NULL, NULL, NULL
diff --git a/src/backend/utils/misc/postgresql.conf.sample b/src/backend/utils/misc/postgresql.conf.sample
index 079efa1baa..360f290a96 100644
--- a/src/backend/utils/misc/postgresql.conf.sample
+++ b/src/backend/utils/misc/postgresql.conf.sample
@@ -408,6 +408,7 @@
 #enable_tidscan = on
 #enable_group_by_reordering = on
 #enable_distinct_reordering = on
+#use_invisible_index = off		# forces planner to consider invisible indexes
 
 # - Planner Cost Constants -
 
diff --git a/src/bin/pg_dump/pg_dump.c b/src/bin/pg_dump/pg_dump.c
index 02e1fdf8f7..167d39edee 100644
--- a/src/bin/pg_dump/pg_dump.c
+++ b/src/bin/pg_dump/pg_dump.c
@@ -7444,7 +7444,8 @@ getIndexes(Archive *fout, TableInfo tblinfo[], int numTables)
 				i_tablespace,
 				i_indreloptions,
 				i_indstatcols,
-				i_indstatvals;
+				i_indstatvals,
+				i_indisvisible;
 
 	/*
 	 * We want to perform just one query against pg_index.  However, we
@@ -7479,7 +7480,7 @@ getIndexes(Archive *fout, TableInfo tblinfo[], int numTables)
 						 "SELECT t.tableoid, t.oid, i.indrelid, "
 						 "t.relname AS indexname, "
 						 "pg_catalog.pg_get_indexdef(i.indexrelid) AS indexdef, "
-						 "i.indkey, i.indisclustered, "
+						 "i.indkey, i.indisclustered, i.indisvisible, "
 						 "c.contype, c.conname, "
 						 "c.condeferrable, c.condeferred, "
 						 "c.tableoid AS contableoid, "
@@ -7496,6 +7497,13 @@ getIndexes(Archive *fout, TableInfo tblinfo[], int numTables)
 		appendPQExpBufferStr(query,
 							 "false AS indisreplident, ");
 
+	if (fout->remoteVersion >= 180000)
+		appendPQExpBufferStr(query,
+							 "i.indisvisible, ");
+	else
+		appendPQExpBufferStr(query,
+							 "true AS indisvisible, ");
+
 	if (fout->remoteVersion >= 110000)
 		appendPQExpBufferStr(query,
 							 "inh.inhparent AS parentidx, "
@@ -7605,6 +7613,7 @@ getIndexes(Archive *fout, TableInfo tblinfo[], int numTables)
 	i_indreloptions = PQfnumber(res, "indreloptions");
 	i_indstatcols = PQfnumber(res, "indstatcols");
 	i_indstatvals = PQfnumber(res, "indstatvals");
+	i_indisvisible = PQfnumber(res, "indisvisible");
 
 	indxinfo = (IndxInfo *) pg_malloc(ntups * sizeof(IndxInfo));
 
@@ -7676,6 +7685,7 @@ getIndexes(Archive *fout, TableInfo tblinfo[], int numTables)
 			{
 				NULL, NULL
 			};
+			indxinfo[j].indisvisible = (PQgetvalue(res, j, i_indisvisible)[0] == 't');
 			contype = *(PQgetvalue(res, j, i_contype));
 
 			if (contype == 'p' || contype == 'u' || contype == 'x')
@@ -17431,6 +17441,12 @@ dumpConstraint(Archive *fout, const ConstraintInfo *coninfo)
 			}
 
 			appendPQExpBufferStr(q, ";\n");
+
+			if (!indxinfo->indisvisible)
+			{
+				appendPQExpBuffer(q, "ALTER INDEX %s INVISIBLE;\n",
+								  fmtQualifiedDumpable(indxinfo));
+			}
 		}
 
 		/*
diff --git a/src/bin/pg_dump/pg_dump.h b/src/bin/pg_dump/pg_dump.h
index 7139c88a69..523fab3dca 100644
--- a/src/bin/pg_dump/pg_dump.h
+++ b/src/bin/pg_dump/pg_dump.h
@@ -421,6 +421,8 @@ typedef struct _indxInfo
 
 	/* if there is an associated constraint object, its dumpId: */
 	DumpId		indexconstraint;
+
+	bool			indisvisible;
 } IndxInfo;
 
 typedef struct _indexAttachInfo
diff --git a/src/bin/pg_dump/t/002_pg_dump.pl b/src/bin/pg_dump/t/002_pg_dump.pl
index 805ba9f49f..8f96394b6a 100644
--- a/src/bin/pg_dump/t/002_pg_dump.pl
+++ b/src/bin/pg_dump/t/002_pg_dump.pl
@@ -2093,6 +2093,35 @@ my %tests = (
 		like => {},
 	},
 
+	'ALTER TABLE ONLY test_table ADD CONSTRAINT ... PRIMARY KEY INVISIBLE' => {
+		create_order => 97,
+		create_sql => 'CREATE TABLE dump_test.test_table_invisible (
+					   id int PRIMARY KEY
+					  );
+					  ALTER INDEX dump_test.test_table_invisible_pkey INVISIBLE;',
+		regexp => qr/^
+			\QALTER TABLE ONLY dump_test.test_table_invisible\E\n\s+
+			\QADD CONSTRAINT test_table_invisible_pkey PRIMARY KEY (id);\E\n
+			\QALTER INDEX dump_test.test_table_invisible_pkey INVISIBLE;\E
+			/xm,
+		like => { %full_runs, %dump_test_schema_runs, section_post_data => 1 },
+		unlike => { exclude_dump_test_schema => 1, only_dump_measurement => 1 },
+	},
+
+	'CREATE INDEX ... INVISIBLE' => {
+		create_order => 98,
+		create_sql => 'CREATE TABLE dump_test.test_table_mixed_indexes (
+					   id int,
+					   value int
+					  );
+					  CREATE INDEX idx_visible ON dump_test.test_table_mixed_indexes(value);
+					  CREATE UNIQUE INDEX idx_invisible ON dump_test.test_table_mixed_indexes(value) INVISIBLE;
+					  ALTER INDEX dump_test.idx_invisible INVISIBLE;',
+		regexp => qr/CREATE UNIQUE INDEX idx_invisible ON dump_test\.test_table_mixed_indexes USING btree \(value\) INVISIBLE;/m,
+		like => { %full_runs, %dump_test_schema_runs, section_post_data => 1 },
+		unlike => { exclude_dump_test_schema => 1, only_dump_measurement => 1 },
+	},
+
 	'CREATE AGGREGATE dump_test.newavg' => {
 		create_order => 25,
 		create_sql => 'CREATE AGGREGATE dump_test.newavg (
diff --git a/src/bin/psql/describe.c b/src/bin/psql/describe.c
index aa4363b200..ca9dba6691 100644
--- a/src/bin/psql/describe.c
+++ b/src/bin/psql/describe.c
@@ -2319,6 +2319,11 @@ describeOneTableDetails(const char *schemaname,
 		else
 			appendPQExpBufferStr(&buf, "false AS indnullsnotdistinct,\n");
 
+		if (pset.sversion >= 180000)
+			appendPQExpBufferStr(&buf, "i.indisvisible,\n");
+		else
+			appendPQExpBufferStr(&buf, "true AS indisvisible,\n");
+
 		appendPQExpBuffer(&buf, "  a.amname, c2.relname, "
 						  "pg_catalog.pg_get_expr(i.indpred, i.indrelid, true)\n"
 						  "FROM pg_catalog.pg_index i, pg_catalog.pg_class c, pg_catalog.pg_class c2, pg_catalog.pg_am a\n"
@@ -2344,9 +2349,10 @@ describeOneTableDetails(const char *schemaname,
 			char	   *deferred = PQgetvalue(result, 0, 5);
 			char	   *indisreplident = PQgetvalue(result, 0, 6);
 			char	   *indnullsnotdistinct = PQgetvalue(result, 0, 7);
-			char	   *indamname = PQgetvalue(result, 0, 8);
-			char	   *indtable = PQgetvalue(result, 0, 9);
-			char	   *indpred = PQgetvalue(result, 0, 10);
+			char	   *indisvisible = PQgetvalue(result, 0, 8);
+			char	   *indamname = PQgetvalue(result, 0, 9);
+			char	   *indtable = PQgetvalue(result, 0, 10);
+			char	   *indpred = PQgetvalue(result, 0, 11);
 
 			if (strcmp(indisprimary, "t") == 0)
 				printfPQExpBuffer(&tmpbuf, _("primary key, "));
@@ -2383,6 +2389,9 @@ describeOneTableDetails(const char *schemaname,
 			if (strcmp(indisreplident, "t") == 0)
 				appendPQExpBufferStr(&tmpbuf, _(", replica identity"));
 
+			if (strcmp(indisvisible, "t") != 0)
+				appendPQExpBufferStr(&tmpbuf, _(", invisible"));
+
 			printTableAddFooter(&cont, tmpbuf.data);
 
 			/*
diff --git a/src/bin/psql/tab-complete.in.c b/src/bin/psql/tab-complete.in.c
index 81cbf10aa2..43ea8e55fd 100644
--- a/src/bin/psql/tab-complete.in.c
+++ b/src/bin/psql/tab-complete.in.c
@@ -2393,7 +2393,8 @@ match_previous_words(int pattern_id,
 	else if (Matches("ALTER", "INDEX", MatchAny))
 		COMPLETE_WITH("ALTER COLUMN", "OWNER TO", "RENAME TO", "SET",
 					  "RESET", "ATTACH PARTITION",
-					  "DEPENDS ON EXTENSION", "NO DEPENDS ON EXTENSION");
+					  "DEPENDS ON EXTENSION", "NO DEPENDS ON EXTENSION",
+					  "INVISIBLE", "VISIBLE");
 	else if (Matches("ALTER", "INDEX", MatchAny, "ATTACH"))
 		COMPLETE_WITH("PARTITION");
 	else if (Matches("ALTER", "INDEX", MatchAny, "ATTACH", "PARTITION"))
diff --git a/src/include/catalog/index.h b/src/include/catalog/index.h
index 4daa8bef5e..75bef5bd88 100644
--- a/src/include/catalog/index.h
+++ b/src/include/catalog/index.h
@@ -65,6 +65,7 @@ extern void index_check_primary_key(Relation heapRel,
 #define	INDEX_CREATE_IF_NOT_EXISTS			(1 << 4)
 #define	INDEX_CREATE_PARTITIONED			(1 << 5)
 #define INDEX_CREATE_INVALID				(1 << 6)
+#define INDEX_CREATE_VISIBLE				(1 << 7)
 
 extern Oid	index_create(Relation heapRelation,
 						 const char *indexRelationName,
@@ -175,7 +176,6 @@ extern void RestoreReindexState(const void *reindexstate);
 
 extern void IndexSetParentIndex(Relation partitionIdx, Oid parentOid);
 
-
 /*
  * itemptr_encode - Encode ItemPointer as int64/int8
  *
diff --git a/src/include/catalog/pg_index.h b/src/include/catalog/pg_index.h
index 4392b9d221..cf1bea9c81 100644
--- a/src/include/catalog/pg_index.h
+++ b/src/include/catalog/pg_index.h
@@ -44,6 +44,7 @@ CATALOG(pg_index,2610,IndexRelationId) BKI_SCHEMA_MACRO
 	bool		indisready;		/* is this index ready for inserts? */
 	bool		indislive;		/* is this index alive at all? */
 	bool		indisreplident; /* is this index the identity for replication? */
+	bool		indisvisible BKI_DEFAULT(t);	/* is this index visible for use by queries? */
 
 	/* variable-length fields start here, but we allow direct access to indkey */
 	int2vector	indkey BKI_FORCE_NOT_NULL;	/* column numbers of indexed cols,
diff --git a/src/include/nodes/parsenodes.h b/src/include/nodes/parsenodes.h
index ffe155ee20..b5b7a8d8c1 100644
--- a/src/include/nodes/parsenodes.h
+++ b/src/include/nodes/parsenodes.h
@@ -2467,6 +2467,8 @@ typedef enum AlterTableType
 	AT_SetIdentity,				/* SET identity column options */
 	AT_DropIdentity,			/* DROP IDENTITY */
 	AT_ReAddStatistics,			/* internal to commands/tablecmds.c */
+	AT_SetIndexVisible,			/* Set INDEX visible */
+	AT_SetIndexInvisible,		/* Set INDEX invisible */
 } AlterTableType;
 
 typedef struct ReplicaIdentityStmt
@@ -3449,6 +3451,7 @@ typedef struct IndexStmt
 	bool		if_not_exists;	/* just do nothing if index already exists? */
 	bool		reset_default_tblspc;	/* reset default_tablespace prior to
 										 * executing */
+  bool		isvisible;		/* true if VISIBLE (default), false if INVISIBLE */
 } IndexStmt;
 
 /* ----------------------
diff --git a/src/include/optimizer/optimizer.h b/src/include/optimizer/optimizer.h
index bcf8ed645c..99e435076a 100644
--- a/src/include/optimizer/optimizer.h
+++ b/src/include/optimizer/optimizer.h
@@ -205,4 +205,9 @@ extern List *pull_var_clause(Node *node, int flags);
 extern Node *flatten_join_alias_vars(PlannerInfo *root, Query *query, Node *node);
 extern Node *flatten_group_exprs(PlannerInfo *root, Query *query, Node *node);
 
+/*
+ * GUC to tell planner to consider invisible indexes.
+ */
+extern bool use_invisible_index;
+
 #endif							/* OPTIMIZER_H */
diff --git a/src/include/parser/kwlist.h b/src/include/parser/kwlist.h
index cf2917ad07..a7235736e0 100644
--- a/src/include/parser/kwlist.h
+++ b/src/include/parser/kwlist.h
@@ -229,6 +229,7 @@ PG_KEYWORD("integer", INTEGER, COL_NAME_KEYWORD, BARE_LABEL)
 PG_KEYWORD("intersect", INTERSECT, RESERVED_KEYWORD, AS_LABEL)
 PG_KEYWORD("interval", INTERVAL, COL_NAME_KEYWORD, BARE_LABEL)
 PG_KEYWORD("into", INTO, RESERVED_KEYWORD, AS_LABEL)
+PG_KEYWORD("invisible", INVISIBLE, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("invoker", INVOKER, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("is", IS, TYPE_FUNC_NAME_KEYWORD, BARE_LABEL)
 PG_KEYWORD("isnull", ISNULL, TYPE_FUNC_NAME_KEYWORD, AS_LABEL)
@@ -491,6 +492,7 @@ PG_KEYWORD("verbose", VERBOSE, TYPE_FUNC_NAME_KEYWORD, BARE_LABEL)
 PG_KEYWORD("version", VERSION_P, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("view", VIEW, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("views", VIEWS, UNRESERVED_KEYWORD, BARE_LABEL)
+PG_KEYWORD("visible", VISIBLE, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("volatile", VOLATILE, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("when", WHEN, RESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("where", WHERE, RESERVED_KEYWORD, AS_LABEL)
diff --git a/src/include/utils/guc_hooks.h b/src/include/utils/guc_hooks.h
index 87999218d6..909f9b57ed 100644
--- a/src/include/utils/guc_hooks.h
+++ b/src/include/utils/guc_hooks.h
@@ -174,5 +174,6 @@ extern void assign_wal_sync_method(int new_wal_sync_method, void *extra);
 extern bool check_synchronized_standby_slots(char **newval, void **extra,
 											 GucSource source);
 extern void assign_synchronized_standby_slots(const char *newval, void *extra);
+extern void assign_use_invisible_index(bool newval, void *extra);
 
 #endif							/* GUC_HOOKS_H */
diff --git a/src/test/modules/test_ddl_deparse/Makefile b/src/test/modules/test_ddl_deparse/Makefile
index 3a57a95c84..747d8b5835 100644
--- a/src/test/modules/test_ddl_deparse/Makefile
+++ b/src/test/modules/test_ddl_deparse/Makefile
@@ -27,7 +27,8 @@ REGRESS = test_ddl_deparse \
 	alter_type_enum \
 	opfamily \
 	defprivs \
-	matviews
+	matviews \
+	alter_index
 
 EXTRA_INSTALL = contrib/pg_stat_statements
 
diff --git a/src/test/modules/test_ddl_deparse/expected/alter_index.out b/src/test/modules/test_ddl_deparse/expected/alter_index.out
new file mode 100644
index 0000000000..f502baf1c5
--- /dev/null
+++ b/src/test/modules/test_ddl_deparse/expected/alter_index.out
@@ -0,0 +1,29 @@
+-- Test index visibility commands
+CREATE TABLE visibility_test (id int);
+NOTICE:  DDL test: type simple, tag CREATE TABLE
+CREATE INDEX idx_vis ON visibility_test(id);
+NOTICE:  DDL test: type simple, tag CREATE INDEX
+ALTER INDEX idx_vis INVISIBLE;
+NOTICE:  DDL test: type alter table, tag ALTER INDEX
+NOTICE:    subcommand: type SET INVISIBLE desc <NULL>
+ALTER INDEX idx_vis VISIBLE;
+NOTICE:  DDL test: type alter table, tag ALTER INDEX
+NOTICE:    subcommand: type SET VISIBLE desc <NULL>
+ALTER INDEX idx_vis INVISIBLE;
+NOTICE:  DDL test: type alter table, tag ALTER INDEX
+NOTICE:    subcommand: type SET INVISIBLE desc <NULL>
+REINDEX INDEX idx_vis;
+NOTICE:  DDL test: type simple, tag REINDEX
+CREATE SCHEMA visibility_schema;
+NOTICE:  DDL test: type simple, tag CREATE SCHEMA
+CREATE TABLE visibility_schema.test2 (id int);
+NOTICE:  DDL test: type simple, tag CREATE TABLE
+CREATE INDEX idx_vis2 ON visibility_schema.test2(id);
+NOTICE:  DDL test: type simple, tag CREATE INDEX
+ALTER INDEX visibility_schema.idx_vis2 INVISIBLE;
+NOTICE:  DDL test: type alter table, tag ALTER INDEX
+NOTICE:    subcommand: type SET INVISIBLE desc <NULL>
+-- Clean up
+DROP SCHEMA visibility_schema CASCADE;
+NOTICE:  drop cascades to table visibility_schema.test2
+DROP TABLE visibility_test CASCADE;
diff --git a/src/test/modules/test_ddl_deparse/sql/alter_index.sql b/src/test/modules/test_ddl_deparse/sql/alter_index.sql
new file mode 100644
index 0000000000..7a34dc6692
--- /dev/null
+++ b/src/test/modules/test_ddl_deparse/sql/alter_index.sql
@@ -0,0 +1,18 @@
+-- Test index visibility commands
+CREATE TABLE visibility_test (id int);
+CREATE INDEX idx_vis ON visibility_test(id);
+
+ALTER INDEX idx_vis INVISIBLE;
+ALTER INDEX idx_vis VISIBLE;
+
+ALTER INDEX idx_vis INVISIBLE;
+REINDEX INDEX idx_vis;
+
+CREATE SCHEMA visibility_schema;
+CREATE TABLE visibility_schema.test2 (id int);
+CREATE INDEX idx_vis2 ON visibility_schema.test2(id);
+ALTER INDEX visibility_schema.idx_vis2 INVISIBLE;
+
+-- Clean up
+DROP SCHEMA visibility_schema CASCADE;
+DROP TABLE visibility_test CASCADE;
diff --git a/src/test/modules/test_ddl_deparse/test_ddl_deparse.c b/src/test/modules/test_ddl_deparse/test_ddl_deparse.c
index 193669f2bc..8d7c7e5894 100644
--- a/src/test/modules/test_ddl_deparse/test_ddl_deparse.c
+++ b/src/test/modules/test_ddl_deparse/test_ddl_deparse.c
@@ -308,6 +308,12 @@ get_altertable_subcmdinfo(PG_FUNCTION_ARGS)
 			case AT_ReAddStatistics:
 				strtype = "(re) ADD STATS";
 				break;
+			case AT_SetIndexVisible:
+				strtype = "SET VISIBLE";
+				break;
+			case AT_SetIndexInvisible:
+				strtype = "SET INVISIBLE";
+				break;
 		}
 
 		if (subcmd->recurse)
diff --git a/src/test/regress/expected/create_index.out b/src/test/regress/expected/create_index.out
index 8011c141bf..60e7e0c616 100644
--- a/src/test/regress/expected/create_index.out
+++ b/src/test/regress/expected/create_index.out
@@ -3331,6 +3331,801 @@ ERROR:  REINDEX SCHEMA cannot run inside a transaction block
 END;
 -- concurrently
 REINDEX SCHEMA CONCURRENTLY schema_to_reindex;
+-- Test index visibility functionality
+CREATE TABLE index_test(
+    id INT PRIMARY KEY,
+    data TEXT,
+    num INT,
+    vector INT[],
+    range INT4RANGE
+);
+INSERT INTO index_test
+SELECT
+    g,
+    'data ' || g,
+    g % 100,
+    ARRAY[g, g+1, g+2],
+    int4range(g, g+10)
+FROM generate_series(1, 1000) g;
+-- Function for testing
+CREATE FUNCTION get_data_length(text) RETURNS INT AS $$
+    SELECT length($1);
+$$ LANGUAGE SQL IMMUTABLE;
+-- Helper function to show index status
+CREATE OR REPLACE FUNCTION show_index_status(index_name text)
+RETURNS TABLE (
+    indexrelid regclass,
+    indisvalid boolean,
+    indisready boolean,
+    indislive boolean,
+    indisvisible boolean
+) AS $$
+BEGIN
+    RETURN QUERY EXECUTE format('
+        SELECT indexrelid::regclass, indisvalid, indisready, indislive, indisvisible
+        FROM pg_index
+        WHERE indexrelid = %L::regclass', index_name);
+END;
+$$ LANGUAGE plpgsql;
+-- Create and test each index type
+-- 1. Basic single-column index
+CREATE INDEX idx_single ON index_test(data);
+SELECT show_index_status('idx_single');
+  show_index_status   
+----------------------
+ (idx_single,t,t,t,t)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE data = 'data 500';
+                  QUERY PLAN                   
+-----------------------------------------------
+ Bitmap Heap Scan on index_test
+   Recheck Cond: (data = 'data 500'::text)
+   ->  Bitmap Index Scan on idx_single
+         Index Cond: (data = 'data 500'::text)
+(4 rows)
+
+ALTER INDEX idx_single INVISIBLE;
+SELECT show_index_status('idx_single');
+  show_index_status   
+----------------------
+ (idx_single,t,t,t,f)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE data = 'data 500';
+             QUERY PLAN              
+-------------------------------------
+ Seq Scan on index_test
+   Filter: (data = 'data 500'::text)
+(2 rows)
+
+ALTER INDEX idx_single VISIBLE;
+SELECT show_index_status('idx_single');
+  show_index_status   
+----------------------
+ (idx_single,t,t,t,t)
+(1 row)
+
+-- 2. Multi-column index
+CREATE INDEX idx_multi ON index_test(num, data);
+SELECT show_index_status('idx_multi');
+  show_index_status  
+---------------------
+ (idx_multi,t,t,t,t)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE num = 50 AND data > 'data 500';
+                           QUERY PLAN                           
+----------------------------------------------------------------
+ Bitmap Heap Scan on index_test
+   Recheck Cond: ((num = 50) AND (data > 'data 500'::text))
+   ->  Bitmap Index Scan on idx_multi
+         Index Cond: ((num = 50) AND (data > 'data 500'::text))
+(4 rows)
+
+ALTER INDEX idx_multi INVISIBLE;
+SELECT show_index_status('idx_multi');
+  show_index_status  
+---------------------
+ (idx_multi,t,t,t,f)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE num = 50 AND data > 'data 500';
+                      QUERY PLAN                      
+------------------------------------------------------
+ Seq Scan on index_test
+   Filter: ((data > 'data 500'::text) AND (num = 50))
+(2 rows)
+
+ALTER INDEX idx_multi VISIBLE;
+SELECT show_index_status('idx_multi');
+  show_index_status  
+---------------------
+ (idx_multi,t,t,t,t)
+(1 row)
+
+-- 3. Partial index
+CREATE INDEX idx_partial ON index_test(num) WHERE num < 50;
+SELECT show_index_status('idx_partial');
+   show_index_status   
+-----------------------
+ (idx_partial,t,t,t,t)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE num = 25;
+               QUERY PLAN               
+----------------------------------------
+ Bitmap Heap Scan on index_test
+   Recheck Cond: (num = 25)
+   ->  Bitmap Index Scan on idx_partial
+         Index Cond: (num = 25)
+(4 rows)
+
+ALTER INDEX idx_partial INVISIBLE;
+SELECT show_index_status('idx_partial');
+   show_index_status   
+-----------------------
+ (idx_partial,t,t,t,f)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE num = 25;
+              QUERY PLAN              
+--------------------------------------
+ Bitmap Heap Scan on index_test
+   Recheck Cond: (num = 25)
+   ->  Bitmap Index Scan on idx_multi
+         Index Cond: (num = 25)
+(4 rows)
+
+ALTER INDEX idx_partial VISIBLE;
+SELECT show_index_status('idx_partial');
+   show_index_status   
+-----------------------
+ (idx_partial,t,t,t,t)
+(1 row)
+
+-- 4. Expression index
+CREATE INDEX idx_expression ON index_test((lower(data)));
+SELECT show_index_status('idx_expression');
+    show_index_status     
+--------------------------
+ (idx_expression,t,t,t,t)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE lower(data) = 'data 500';
+                      QUERY PLAN                      
+------------------------------------------------------
+ Bitmap Heap Scan on index_test
+   Recheck Cond: (lower(data) = 'data 500'::text)
+   ->  Bitmap Index Scan on idx_expression
+         Index Cond: (lower(data) = 'data 500'::text)
+(4 rows)
+
+ALTER INDEX idx_expression INVISIBLE;
+SELECT show_index_status('idx_expression');
+    show_index_status     
+--------------------------
+ (idx_expression,t,t,t,f)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE lower(data) = 'data 500';
+                 QUERY PLAN                 
+--------------------------------------------
+ Seq Scan on index_test
+   Filter: (lower(data) = 'data 500'::text)
+(2 rows)
+
+ALTER INDEX idx_expression VISIBLE;
+SELECT show_index_status('idx_expression');
+    show_index_status     
+--------------------------
+ (idx_expression,t,t,t,t)
+(1 row)
+
+-- 5. GIN index
+CREATE INDEX idx_gin ON index_test USING gin(vector);
+SELECT show_index_status('idx_gin');
+ show_index_status 
+-------------------
+ (idx_gin,t,t,t,t)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE vector @> ARRAY[500];
+                     QUERY PLAN                     
+----------------------------------------------------
+ Bitmap Heap Scan on index_test
+   Recheck Cond: (vector @> '{500}'::integer[])
+   ->  Bitmap Index Scan on idx_gin
+         Index Cond: (vector @> '{500}'::integer[])
+(4 rows)
+
+ALTER INDEX idx_gin INVISIBLE;
+SELECT show_index_status('idx_gin');
+ show_index_status 
+-------------------
+ (idx_gin,t,t,t,f)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE vector @> ARRAY[500];
+                QUERY PLAN                
+------------------------------------------
+ Seq Scan on index_test
+   Filter: (vector @> '{500}'::integer[])
+(2 rows)
+
+ALTER INDEX idx_gin VISIBLE;
+SELECT show_index_status('idx_gin');
+ show_index_status 
+-------------------
+ (idx_gin,t,t,t,t)
+(1 row)
+
+-- 6. GiST index
+CREATE INDEX idx_gist ON index_test USING gist(range);
+SELECT show_index_status('idx_gist');
+ show_index_status  
+--------------------
+ (idx_gist,t,t,t,t)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE range && int4range(100, 110);
+                      QUERY PLAN                       
+-------------------------------------------------------
+ Bitmap Heap Scan on index_test
+   Recheck Cond: (range && '[100,110)'::int4range)
+   ->  Bitmap Index Scan on idx_gist
+         Index Cond: (range && '[100,110)'::int4range)
+(4 rows)
+
+ALTER INDEX idx_gist INVISIBLE;
+SELECT show_index_status('idx_gist');
+ show_index_status  
+--------------------
+ (idx_gist,t,t,t,f)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE range && int4range(100, 110);
+                 QUERY PLAN                  
+---------------------------------------------
+ Seq Scan on index_test
+   Filter: (range && '[100,110)'::int4range)
+(2 rows)
+
+ALTER INDEX idx_gist VISIBLE;
+SELECT show_index_status('idx_gist');
+ show_index_status  
+--------------------
+ (idx_gist,t,t,t,t)
+(1 row)
+
+-- 7. Covering index
+CREATE INDEX idx_covering ON index_test(num) INCLUDE (data);
+SELECT show_index_status('idx_covering');
+   show_index_status    
+------------------------
+ (idx_covering,t,t,t,t)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT num, data FROM index_test WHERE num = 50;
+               QUERY PLAN                
+-----------------------------------------
+ Bitmap Heap Scan on index_test
+   Recheck Cond: (num = 50)
+   ->  Bitmap Index Scan on idx_covering
+         Index Cond: (num = 50)
+(4 rows)
+
+ALTER INDEX idx_covering INVISIBLE;
+SELECT show_index_status('idx_covering');
+   show_index_status    
+------------------------
+ (idx_covering,t,t,t,f)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT num, data FROM index_test WHERE num = 50;
+              QUERY PLAN              
+--------------------------------------
+ Bitmap Heap Scan on index_test
+   Recheck Cond: (num = 50)
+   ->  Bitmap Index Scan on idx_multi
+         Index Cond: (num = 50)
+(4 rows)
+
+ALTER INDEX idx_covering VISIBLE;
+SELECT show_index_status('idx_covering');
+   show_index_status    
+------------------------
+ (idx_covering,t,t,t,t)
+(1 row)
+
+-- 8. Unique index
+CREATE UNIQUE INDEX idx_unique ON index_test(id, data);
+SELECT show_index_status('idx_unique');
+  show_index_status   
+----------------------
+ (idx_unique,t,t,t,t)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE id = 500 AND data = 'data 500';
+                        QUERY PLAN                        
+----------------------------------------------------------
+ Index Scan using idx_unique on index_test
+   Index Cond: ((id = 500) AND (data = 'data 500'::text))
+(2 rows)
+
+ALTER INDEX idx_unique INVISIBLE;
+SELECT show_index_status('idx_unique');
+  show_index_status   
+----------------------
+ (idx_unique,t,t,t,f)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE id = 500 AND data = 'data 500';
+                   QUERY PLAN                   
+------------------------------------------------
+ Index Scan using index_test_pkey on index_test
+   Index Cond: (id = 500)
+   Filter: (data = 'data 500'::text)
+(3 rows)
+
+ALTER INDEX idx_unique VISIBLE;
+SELECT show_index_status('idx_unique');
+  show_index_status   
+----------------------
+ (idx_unique,t,t,t,t)
+(1 row)
+
+-- 9. Function-based index
+CREATE INDEX idx_func ON index_test(get_data_length(data));
+SELECT show_index_status('idx_func');
+ show_index_status  
+--------------------
+ (idx_func,t,t,t,t)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE get_data_length(data) = 10;
+               QUERY PLAN                
+-----------------------------------------
+ Bitmap Heap Scan on index_test
+   Recheck Cond: (length(data) = 10)
+   ->  Bitmap Index Scan on idx_func
+         Index Cond: (length(data) = 10)
+(4 rows)
+
+ALTER INDEX idx_func INVISIBLE;
+SELECT show_index_status('idx_func');
+ show_index_status  
+--------------------
+ (idx_func,t,t,t,f)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE get_data_length(data) = 10;
+          QUERY PLAN           
+-------------------------------
+ Seq Scan on index_test
+   Filter: (length(data) = 10)
+(2 rows)
+
+ALTER INDEX idx_func VISIBLE;
+SELECT show_index_status('idx_func');
+ show_index_status  
+--------------------
+ (idx_func,t,t,t,t)
+(1 row)
+
+-- 10. Join index
+CREATE TABLE join_test (id INT PRIMARY KEY, ref_id INT);
+INSERT INTO join_test SELECT g, g % 100 FROM generate_series(1, 1000) g;
+CREATE INDEX idx_join ON join_test(ref_id);
+SELECT show_index_status('idx_join');
+ show_index_status  
+--------------------
+ (idx_join,t,t,t,t)
+(1 row)
+
+EXPLAIN (COSTS OFF)
+SELECT jt.id, it.data
+FROM join_test jt
+JOIN index_test it ON jt.ref_id = it.num
+WHERE jt.id BETWEEN 100 AND 200;
+                          QUERY PLAN                           
+---------------------------------------------------------------
+ Hash Join
+   Hash Cond: (it.num = jt.ref_id)
+   ->  Seq Scan on index_test it
+   ->  Hash
+         ->  Bitmap Heap Scan on join_test jt
+               Recheck Cond: ((id >= 100) AND (id <= 200))
+               ->  Bitmap Index Scan on join_test_pkey
+                     Index Cond: ((id >= 100) AND (id <= 200))
+(8 rows)
+
+-- Set all indexes to invisible to force seq scan
+ALTER INDEX idx_join INVISIBLE;
+ALTER INDEX join_test_pkey INVISIBLE;
+SELECT show_index_status('idx_join');
+ show_index_status  
+--------------------
+ (idx_join,t,t,t,f)
+(1 row)
+
+SELECT show_index_status('join_test_pkey');
+    show_index_status     
+--------------------------
+ (join_test_pkey,t,t,t,f)
+(1 row)
+
+EXPLAIN (COSTS OFF)
+SELECT jt.id, it.data
+FROM join_test jt
+JOIN index_test it ON jt.ref_id = it.num
+WHERE jt.id BETWEEN 100 AND 200;
+                     QUERY PLAN                      
+-----------------------------------------------------
+ Hash Join
+   Hash Cond: (it.num = jt.ref_id)
+   ->  Seq Scan on index_test it
+   ->  Hash
+         ->  Seq Scan on join_test jt
+               Filter: ((id >= 100) AND (id <= 200))
+(6 rows)
+
+ALTER INDEX idx_join VISIBLE;
+ALTER INDEX join_test_pkey VISIBLE;
+SELECT show_index_status('idx_join');
+ show_index_status  
+--------------------
+ (idx_join,t,t,t,t)
+(1 row)
+
+SELECT show_index_status('join_test_pkey');
+    show_index_status     
+--------------------------
+ (join_test_pkey,t,t,t,t)
+(1 row)
+
+-- Test REINDEX CONCURRENTLY
+REINDEX INDEX CONCURRENTLY idx_join;
+SELECT show_index_status('idx_join');
+ show_index_status  
+--------------------
+ (idx_join,t,t,t,t)
+(1 row)
+
+ALTER INDEX idx_join INVISIBLE;
+SELECT show_index_status('idx_join');
+ show_index_status  
+--------------------
+ (idx_join,t,t,t,f)
+(1 row)
+
+REINDEX INDEX CONCURRENTLY idx_join;
+SELECT show_index_status('idx_join');
+ show_index_status  
+--------------------
+ (idx_join,t,t,t,f)
+(1 row)
+
+SELECT pg_get_indexdef('idx_join'::regclass);
+                                   pg_get_indexdef                                   
+-------------------------------------------------------------------------------------
+ CREATE INDEX idx_join ON schema_to_reindex.join_test USING btree (ref_id) INVISIBLE
+(1 row)
+
+ALTER INDEX idx_join VISIBLE;
+SELECT pg_get_indexdef('idx_join'::regclass);
+                              pg_get_indexdef                              
+---------------------------------------------------------------------------
+ CREATE INDEX idx_join ON schema_to_reindex.join_test USING btree (ref_id)
+(1 row)
+
+-- Test index visibility with indcheckxmin being true
+CREATE TABLE indcheckxmin_test(id int PRIMARY KEY);
+INSERT INTO indcheckxmin_test VALUES (1), (2), (3);
+CREATE INDEX CONCURRENTLY idx_checkxmin ON indcheckxmin_test(id);
+BEGIN;
+-- Simulate indcheckxmin being true
+UPDATE pg_index SET indcheckxmin = true WHERE indexrelid = 'idx_checkxmin'::regclass;
+ALTER INDEX idx_checkxmin INVISIBLE;  -- expect fail
+ERROR:  cannot update index visibility while indcheckxmin is true
+HINT:  Wait for all transactions that might see inconsistent HOT chains to complete
+ROLLBACK;
+-- Test prepared statements with index visibility
+CREATE TABLE prep_idx_test (id int, data text);
+CREATE INDEX prep_idx1 ON prep_idx_test(data);
+INSERT INTO prep_idx_test SELECT g, 'data ' || g FROM generate_series(1,100) g;
+-- Test with visible index
+PREPARE idx_plan AS SELECT * FROM prep_idx_test WHERE data = $1;
+EXPLAIN (COSTS OFF) EXECUTE idx_plan('data 1');
+                 QUERY PLAN                  
+---------------------------------------------
+ Bitmap Heap Scan on prep_idx_test
+   Recheck Cond: (data = 'data 1'::text)
+   ->  Bitmap Index Scan on prep_idx1
+         Index Cond: (data = 'data 1'::text)
+(4 rows)
+
+EXECUTE idx_plan('data 1');
+ id |  data  
+----+--------
+  1 | data 1
+(1 row)
+
+-- Test with invisible index
+ALTER INDEX prep_idx1 INVISIBLE;
+EXPLAIN (COSTS OFF) EXECUTE idx_plan('data 1');
+            QUERY PLAN             
+-----------------------------------
+ Seq Scan on prep_idx_test
+   Filter: (data = 'data 1'::text)
+(2 rows)
+
+EXECUTE idx_plan('data 1');
+ id |  data  
+----+--------
+  1 | data 1
+(1 row)
+
+-- Test with use_invisible_index
+SET use_invisible_index TO on;
+EXPLAIN (COSTS OFF) EXECUTE idx_plan('data 1');
+                 QUERY PLAN                  
+---------------------------------------------
+ Bitmap Heap Scan on prep_idx_test
+   Recheck Cond: (data = 'data 1'::text)
+   ->  Bitmap Index Scan on prep_idx1
+         Index Cond: (data = 'data 1'::text)
+(4 rows)
+
+EXECUTE idx_plan('data 1');
+ id |  data  
+----+--------
+  1 | data 1
+(1 row)
+
+SET use_invisible_index TO off;
+-- Assert plan cache is reset and index is not used
+EXPLAIN (COSTS OFF) EXECUTE idx_plan('data 1');
+            QUERY PLAN             
+-----------------------------------
+ Seq Scan on prep_idx_test
+   Filter: (data = 'data 1'::text)
+(2 rows)
+
+-- Make index visible and test again
+ALTER INDEX prep_idx1 VISIBLE;
+EXPLAIN (COSTS OFF) EXECUTE idx_plan('data 1');
+                 QUERY PLAN                  
+---------------------------------------------
+ Bitmap Heap Scan on prep_idx_test
+   Recheck Cond: (data = 'data 1'::text)
+   ->  Bitmap Index Scan on prep_idx1
+         Index Cond: (data = 'data 1'::text)
+(4 rows)
+
+EXECUTE idx_plan('data 1');
+ id |  data  
+----+--------
+  1 | data 1
+(1 row)
+
+-- Test index visibility with partitioned tables
+CREATE TABLE part_tbl(id int, data text) PARTITION BY RANGE(id);
+CREATE TABLE part1 PARTITION OF part_tbl FOR VALUES FROM (1) TO (100);
+CREATE TABLE part2 PARTITION OF part_tbl FOR VALUES FROM (100) TO (200);
+INSERT INTO part_tbl
+SELECT g, 'data ' || g
+FROM generate_series(1, 199) g;
+CREATE INDEX idx_part_tbl ON part_tbl(data);
+SELECT c.relname, i.indisvisible
+FROM pg_index i
+JOIN pg_class c ON i.indexrelid = c.oid
+WHERE c.relname LIKE 'idx_part_tbl%'
+ORDER BY c.relname;
+   relname    | indisvisible 
+--------------+--------------
+ idx_part_tbl | t
+(1 row)
+
+-- Force use of indexes to avoid flaky test results
+SET enable_seqscan = off;
+EXPLAIN (COSTS OFF)
+SELECT * FROM part_tbl WHERE data = 'data 50';
+                        QUERY PLAN                         
+-----------------------------------------------------------
+ Append
+   ->  Index Scan using part1_data_idx on part1 part_tbl_1
+         Index Cond: (data = 'data 50'::text)
+   ->  Index Scan using part2_data_idx on part2 part_tbl_2
+         Index Cond: (data = 'data 50'::text)
+(5 rows)
+
+ALTER INDEX idx_part_tbl INVISIBLE;
+SELECT c.relname, i.indisvisible
+FROM pg_index i
+JOIN pg_class c ON i.indexrelid = c.oid
+WHERE c.relname LIKE 'idx_part_tbl%'
+ORDER BY c.relname;
+   relname    | indisvisible 
+--------------+--------------
+ idx_part_tbl | f
+(1 row)
+
+-- Check query plan after setting invisible (should use seq scan)
+EXPLAIN (COSTS OFF)
+SELECT * FROM part_tbl WHERE data = 'data 50';
+                QUERY PLAN                
+------------------------------------------
+ Append
+   ->  Seq Scan on part1 part_tbl_1
+         Disabled: true
+         Filter: (data = 'data 50'::text)
+   ->  Seq Scan on part2 part_tbl_2
+         Disabled: true
+         Filter: (data = 'data 50'::text)
+(7 rows)
+
+SET use_invisible_index TO on;
+EXPLAIN (COSTS OFF)
+SELECT * FROM part_tbl WHERE data = 'data 50';
+                        QUERY PLAN                         
+-----------------------------------------------------------
+ Append
+   ->  Index Scan using part1_data_idx on part1 part_tbl_1
+         Index Cond: (data = 'data 50'::text)
+   ->  Index Scan using part2_data_idx on part2 part_tbl_2
+         Index Cond: (data = 'data 50'::text)
+(5 rows)
+
+SET use_invisible_index TO off;
+EXPLAIN (COSTS OFF)
+SELECT * FROM part_tbl WHERE data = 'data 50';
+                QUERY PLAN                
+------------------------------------------
+ Append
+   ->  Seq Scan on part1 part_tbl_1
+         Disabled: true
+         Filter: (data = 'data 50'::text)
+   ->  Seq Scan on part2 part_tbl_2
+         Disabled: true
+         Filter: (data = 'data 50'::text)
+(7 rows)
+
+ALTER INDEX idx_part_tbl VISIBLE;
+SELECT c.relname, i.indisvisible
+FROM pg_index i
+JOIN pg_class c ON i.indexrelid = c.oid
+WHERE c.relname LIKE 'idx_part_tbl%'
+ORDER BY c.relname;
+   relname    | indisvisible 
+--------------+--------------
+ idx_part_tbl | t
+(1 row)
+
+EXPLAIN (COSTS OFF)
+SELECT * FROM part_tbl WHERE data = 'data 50';
+                        QUERY PLAN                         
+-----------------------------------------------------------
+ Append
+   ->  Index Scan using part1_data_idx on part1 part_tbl_1
+         Index Cond: (data = 'data 50'::text)
+   ->  Index Scan using part2_data_idx on part2 part_tbl_2
+         Index Cond: (data = 'data 50'::text)
+(5 rows)
+
+SET enable_seqscan = on;
+-- Test REINDEX maintains visibility setting
+ALTER INDEX idx_part_tbl INVISIBLE;
+REINDEX INDEX idx_part_tbl;
+SELECT c.relname, i.indisvisible
+FROM pg_index i
+JOIN pg_class c ON i.indexrelid = c.oid
+WHERE c.relname LIKE 'idx_part_tbl%'
+ORDER BY c.relname;
+   relname    | indisvisible 
+--------------+--------------
+ idx_part_tbl | f
+(1 row)
+
+-- Test that index visibility is preserved after ALTER TABLE
+CREATE TABLE vis_test(id INT PRIMARY KEY, data text);
+\d vis_test
+        Table "schema_to_reindex.vis_test"
+ Column |  Type   | Collation | Nullable | Default 
+--------+---------+-----------+----------+---------
+ id     | integer |           | not null | 
+ data   | text    |           |          | 
+Indexes:
+    "vis_test_pkey" PRIMARY KEY, btree (id)
+
+ALTER INDEX vis_test_pkey INVISIBLE;
+\d vis_test
+        Table "schema_to_reindex.vis_test"
+ Column |  Type   | Collation | Nullable | Default 
+--------+---------+-----------+----------+---------
+ id     | integer |           | not null | 
+ data   | text    |           |          | 
+Indexes:
+    "vis_test_pkey" PRIMARY KEY, btree (id) INVISIBLE
+
+ALTER TABLE vis_test ALTER COLUMN id SET DATA TYPE bigint;
+\d vis_test
+        Table "schema_to_reindex.vis_test"
+ Column |  Type  | Collation | Nullable | Default 
+--------+--------+-----------+----------+---------
+ id     | bigint |           | not null | 
+ data   | text   |           |          | 
+Indexes:
+    "vis_test_pkey" PRIMARY KEY, btree (id) INVISIBLE
+
+ALTER TABLE vis_test ALTER COLUMN id SET DATA TYPE int;
+\d vis_test
+        Table "schema_to_reindex.vis_test"
+ Column |  Type   | Collation | Nullable | Default 
+--------+---------+-----------+----------+---------
+ id     | integer |           | not null | 
+ data   | text    |           |          | 
+Indexes:
+    "vis_test_pkey" PRIMARY KEY, btree (id) INVISIBLE
+
+ALTER INDEX vis_test_pkey VISIBLE;
+\d vis_test
+        Table "schema_to_reindex.vis_test"
+ Column |  Type   | Collation | Nullable | Default 
+--------+---------+-----------+----------+---------
+ id     | integer |           | not null | 
+ data   | text    |           |          | 
+Indexes:
+    "vis_test_pkey" PRIMARY KEY, btree (id)
+
+-- Test CREATE INDEX with INVISIBLE option
+CREATE TABLE invis_test(id int, data text);
+INSERT INTO invis_test SELECT g, 'data ' || g FROM generate_series(1,100) g;
+CREATE INDEX idx_invis1 ON invis_test(data) INVISIBLE;
+\d invis_test
+       Table "schema_to_reindex.invis_test"
+ Column |  Type   | Collation | Nullable | Default 
+--------+---------+-----------+----------+---------
+ id     | integer |           |          | 
+ data   | text    |           |          | 
+Indexes:
+    "idx_invis1" btree (data) INVISIBLE
+
+\d idx_invis1
+Index "schema_to_reindex.idx_invis1"
+ Column | Type | Key? | Definition 
+--------+------+------+------------
+ data   | text | yes  | data
+btree, for table "schema_to_reindex.invis_test", invisible
+
+ALTER INDEX idx_invis1 VISIBLE;
+\d invis_test
+       Table "schema_to_reindex.invis_test"
+ Column |  Type   | Collation | Nullable | Default 
+--------+---------+-----------+----------+---------
+ id     | integer |           |          | 
+ data   | text    |           |          | 
+Indexes:
+    "idx_invis1" btree (data)
+
+\d idx_invis1
+Index "schema_to_reindex.idx_invis1"
+ Column | Type | Key? | Definition 
+--------+------+------+------------
+ data   | text | yes  | data
+btree, for table "schema_to_reindex.invis_test"
+
+-- Clean up
+DROP TABLE index_test;
+DROP TABLE join_test;
+DROP FUNCTION get_data_length;
+DROP FUNCTION show_index_status;
+DROP TABLE indcheckxmin_test CASCADE;
+DEALLOCATE idx_plan;
+DROP TABLE prep_idx_test;
+DROP TABLE part_tbl CASCADE;
+DROP TABLE vis_test;
+DROP TABLE invis_test;
 -- Failure for unauthorized user
 CREATE ROLE regress_reindexuser NOLOGIN;
 SET SESSION ROLE regress_reindexuser;
diff --git a/src/test/regress/sql/create_index.sql b/src/test/regress/sql/create_index.sql
index 068c66b95a..b858630659 100644
--- a/src/test/regress/sql/create_index.sql
+++ b/src/test/regress/sql/create_index.sql
@@ -1415,6 +1415,327 @@ END;
 -- concurrently
 REINDEX SCHEMA CONCURRENTLY schema_to_reindex;
 
+-- Test index visibility functionality
+
+CREATE TABLE index_test(
+    id INT PRIMARY KEY,
+    data TEXT,
+    num INT,
+    vector INT[],
+    range INT4RANGE
+);
+
+INSERT INTO index_test
+SELECT
+    g,
+    'data ' || g,
+    g % 100,
+    ARRAY[g, g+1, g+2],
+    int4range(g, g+10)
+FROM generate_series(1, 1000) g;
+
+-- Function for testing
+CREATE FUNCTION get_data_length(text) RETURNS INT AS $$
+    SELECT length($1);
+$$ LANGUAGE SQL IMMUTABLE;
+
+-- Helper function to show index status
+CREATE OR REPLACE FUNCTION show_index_status(index_name text)
+RETURNS TABLE (
+    indexrelid regclass,
+    indisvalid boolean,
+    indisready boolean,
+    indislive boolean,
+    indisvisible boolean
+) AS $$
+BEGIN
+    RETURN QUERY EXECUTE format('
+        SELECT indexrelid::regclass, indisvalid, indisready, indislive, indisvisible
+        FROM pg_index
+        WHERE indexrelid = %L::regclass', index_name);
+END;
+$$ LANGUAGE plpgsql;
+
+-- Create and test each index type
+-- 1. Basic single-column index
+CREATE INDEX idx_single ON index_test(data);
+SELECT show_index_status('idx_single');
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE data = 'data 500';
+ALTER INDEX idx_single INVISIBLE;
+SELECT show_index_status('idx_single');
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE data = 'data 500';
+ALTER INDEX idx_single VISIBLE;
+SELECT show_index_status('idx_single');
+
+-- 2. Multi-column index
+CREATE INDEX idx_multi ON index_test(num, data);
+SELECT show_index_status('idx_multi');
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE num = 50 AND data > 'data 500';
+ALTER INDEX idx_multi INVISIBLE;
+SELECT show_index_status('idx_multi');
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE num = 50 AND data > 'data 500';
+ALTER INDEX idx_multi VISIBLE;
+SELECT show_index_status('idx_multi');
+
+-- 3. Partial index
+CREATE INDEX idx_partial ON index_test(num) WHERE num < 50;
+SELECT show_index_status('idx_partial');
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE num = 25;
+ALTER INDEX idx_partial INVISIBLE;
+SELECT show_index_status('idx_partial');
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE num = 25;
+ALTER INDEX idx_partial VISIBLE;
+SELECT show_index_status('idx_partial');
+
+-- 4. Expression index
+CREATE INDEX idx_expression ON index_test((lower(data)));
+SELECT show_index_status('idx_expression');
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE lower(data) = 'data 500';
+ALTER INDEX idx_expression INVISIBLE;
+SELECT show_index_status('idx_expression');
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE lower(data) = 'data 500';
+ALTER INDEX idx_expression VISIBLE;
+SELECT show_index_status('idx_expression');
+
+-- 5. GIN index
+CREATE INDEX idx_gin ON index_test USING gin(vector);
+SELECT show_index_status('idx_gin');
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE vector @> ARRAY[500];
+ALTER INDEX idx_gin INVISIBLE;
+SELECT show_index_status('idx_gin');
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE vector @> ARRAY[500];
+ALTER INDEX idx_gin VISIBLE;
+SELECT show_index_status('idx_gin');
+
+-- 6. GiST index
+CREATE INDEX idx_gist ON index_test USING gist(range);
+SELECT show_index_status('idx_gist');
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE range && int4range(100, 110);
+ALTER INDEX idx_gist INVISIBLE;
+SELECT show_index_status('idx_gist');
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE range && int4range(100, 110);
+ALTER INDEX idx_gist VISIBLE;
+SELECT show_index_status('idx_gist');
+
+-- 7. Covering index
+CREATE INDEX idx_covering ON index_test(num) INCLUDE (data);
+SELECT show_index_status('idx_covering');
+EXPLAIN (COSTS OFF) SELECT num, data FROM index_test WHERE num = 50;
+ALTER INDEX idx_covering INVISIBLE;
+SELECT show_index_status('idx_covering');
+EXPLAIN (COSTS OFF) SELECT num, data FROM index_test WHERE num = 50;
+ALTER INDEX idx_covering VISIBLE;
+SELECT show_index_status('idx_covering');
+
+-- 8. Unique index
+CREATE UNIQUE INDEX idx_unique ON index_test(id, data);
+SELECT show_index_status('idx_unique');
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE id = 500 AND data = 'data 500';
+ALTER INDEX idx_unique INVISIBLE;
+SELECT show_index_status('idx_unique');
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE id = 500 AND data = 'data 500';
+ALTER INDEX idx_unique VISIBLE;
+SELECT show_index_status('idx_unique');
+
+-- 9. Function-based index
+CREATE INDEX idx_func ON index_test(get_data_length(data));
+SELECT show_index_status('idx_func');
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE get_data_length(data) = 10;
+ALTER INDEX idx_func INVISIBLE;
+SELECT show_index_status('idx_func');
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE get_data_length(data) = 10;
+ALTER INDEX idx_func VISIBLE;
+SELECT show_index_status('idx_func');
+
+-- 10. Join index
+CREATE TABLE join_test (id INT PRIMARY KEY, ref_id INT);
+INSERT INTO join_test SELECT g, g % 100 FROM generate_series(1, 1000) g;
+CREATE INDEX idx_join ON join_test(ref_id);
+SELECT show_index_status('idx_join');
+
+EXPLAIN (COSTS OFF)
+SELECT jt.id, it.data
+FROM join_test jt
+JOIN index_test it ON jt.ref_id = it.num
+WHERE jt.id BETWEEN 100 AND 200;
+
+-- Set all indexes to invisible to force seq scan
+ALTER INDEX idx_join INVISIBLE;
+ALTER INDEX join_test_pkey INVISIBLE;
+SELECT show_index_status('idx_join');
+SELECT show_index_status('join_test_pkey');
+
+EXPLAIN (COSTS OFF)
+SELECT jt.id, it.data
+FROM join_test jt
+JOIN index_test it ON jt.ref_id = it.num
+WHERE jt.id BETWEEN 100 AND 200;
+
+ALTER INDEX idx_join VISIBLE;
+ALTER INDEX join_test_pkey VISIBLE;
+SELECT show_index_status('idx_join');
+SELECT show_index_status('join_test_pkey');
+
+-- Test REINDEX CONCURRENTLY
+REINDEX INDEX CONCURRENTLY idx_join;
+SELECT show_index_status('idx_join');
+
+ALTER INDEX idx_join INVISIBLE;
+SELECT show_index_status('idx_join');
+REINDEX INDEX CONCURRENTLY idx_join;
+SELECT show_index_status('idx_join');
+
+SELECT pg_get_indexdef('idx_join'::regclass);
+ALTER INDEX idx_join VISIBLE;
+SELECT pg_get_indexdef('idx_join'::regclass);
+
+-- Test index visibility with indcheckxmin being true
+
+CREATE TABLE indcheckxmin_test(id int PRIMARY KEY);
+INSERT INTO indcheckxmin_test VALUES (1), (2), (3);
+CREATE INDEX CONCURRENTLY idx_checkxmin ON indcheckxmin_test(id);
+BEGIN;
+-- Simulate indcheckxmin being true
+UPDATE pg_index SET indcheckxmin = true WHERE indexrelid = 'idx_checkxmin'::regclass;
+ALTER INDEX idx_checkxmin INVISIBLE;  -- expect fail
+ROLLBACK;
+
+-- Test prepared statements with index visibility
+CREATE TABLE prep_idx_test (id int, data text);
+CREATE INDEX prep_idx1 ON prep_idx_test(data);
+INSERT INTO prep_idx_test SELECT g, 'data ' || g FROM generate_series(1,100) g;
+
+-- Test with visible index
+PREPARE idx_plan AS SELECT * FROM prep_idx_test WHERE data = $1;
+EXPLAIN (COSTS OFF) EXECUTE idx_plan('data 1');
+EXECUTE idx_plan('data 1');
+
+-- Test with invisible index
+ALTER INDEX prep_idx1 INVISIBLE;
+EXPLAIN (COSTS OFF) EXECUTE idx_plan('data 1');
+EXECUTE idx_plan('data 1');
+
+-- Test with use_invisible_index
+SET use_invisible_index TO on;
+EXPLAIN (COSTS OFF) EXECUTE idx_plan('data 1');
+EXECUTE idx_plan('data 1');
+SET use_invisible_index TO off;
+-- Assert plan cache is reset and index is not used
+EXPLAIN (COSTS OFF) EXECUTE idx_plan('data 1');
+
+-- Make index visible and test again
+ALTER INDEX prep_idx1 VISIBLE;
+EXPLAIN (COSTS OFF) EXECUTE idx_plan('data 1');
+EXECUTE idx_plan('data 1');
+
+-- Test index visibility with partitioned tables
+CREATE TABLE part_tbl(id int, data text) PARTITION BY RANGE(id);
+CREATE TABLE part1 PARTITION OF part_tbl FOR VALUES FROM (1) TO (100);
+CREATE TABLE part2 PARTITION OF part_tbl FOR VALUES FROM (100) TO (200);
+
+INSERT INTO part_tbl
+SELECT g, 'data ' || g
+FROM generate_series(1, 199) g;
+
+CREATE INDEX idx_part_tbl ON part_tbl(data);
+
+SELECT c.relname, i.indisvisible
+FROM pg_index i
+JOIN pg_class c ON i.indexrelid = c.oid
+WHERE c.relname LIKE 'idx_part_tbl%'
+ORDER BY c.relname;
+
+-- Force use of indexes to avoid flaky test results
+SET enable_seqscan = off;
+
+EXPLAIN (COSTS OFF)
+SELECT * FROM part_tbl WHERE data = 'data 50';
+
+ALTER INDEX idx_part_tbl INVISIBLE;
+
+SELECT c.relname, i.indisvisible
+FROM pg_index i
+JOIN pg_class c ON i.indexrelid = c.oid
+WHERE c.relname LIKE 'idx_part_tbl%'
+ORDER BY c.relname;
+
+-- Check query plan after setting invisible (should use seq scan)
+EXPLAIN (COSTS OFF)
+SELECT * FROM part_tbl WHERE data = 'data 50';
+
+SET use_invisible_index TO on;
+
+EXPLAIN (COSTS OFF)
+SELECT * FROM part_tbl WHERE data = 'data 50';
+
+SET use_invisible_index TO off;
+
+EXPLAIN (COSTS OFF)
+SELECT * FROM part_tbl WHERE data = 'data 50';
+
+ALTER INDEX idx_part_tbl VISIBLE;
+
+SELECT c.relname, i.indisvisible
+FROM pg_index i
+JOIN pg_class c ON i.indexrelid = c.oid
+WHERE c.relname LIKE 'idx_part_tbl%'
+ORDER BY c.relname;
+
+EXPLAIN (COSTS OFF)
+SELECT * FROM part_tbl WHERE data = 'data 50';
+
+SET enable_seqscan = on;
+
+-- Test REINDEX maintains visibility setting
+ALTER INDEX idx_part_tbl INVISIBLE;
+REINDEX INDEX idx_part_tbl;
+
+SELECT c.relname, i.indisvisible
+FROM pg_index i
+JOIN pg_class c ON i.indexrelid = c.oid
+WHERE c.relname LIKE 'idx_part_tbl%'
+ORDER BY c.relname;
+
+-- Test that index visibility is preserved after ALTER TABLE
+CREATE TABLE vis_test(id INT PRIMARY KEY, data text);
+\d vis_test
+
+ALTER INDEX vis_test_pkey INVISIBLE;
+\d vis_test
+
+ALTER TABLE vis_test ALTER COLUMN id SET DATA TYPE bigint;
+\d vis_test
+
+ALTER TABLE vis_test ALTER COLUMN id SET DATA TYPE int;
+\d vis_test
+
+ALTER INDEX vis_test_pkey VISIBLE;
+\d vis_test
+
+-- Test CREATE INDEX with INVISIBLE option
+CREATE TABLE invis_test(id int, data text);
+INSERT INTO invis_test SELECT g, 'data ' || g FROM generate_series(1,100) g;
+
+CREATE INDEX idx_invis1 ON invis_test(data) INVISIBLE;
+\d invis_test
+\d idx_invis1
+
+ALTER INDEX idx_invis1 VISIBLE;
+\d invis_test
+\d idx_invis1
+
+-- Clean up
+DROP TABLE index_test;
+DROP TABLE join_test;
+DROP FUNCTION get_data_length;
+DROP FUNCTION show_index_status;
+DROP TABLE indcheckxmin_test CASCADE;
+DEALLOCATE idx_plan;
+DROP TABLE prep_idx_test;
+DROP TABLE part_tbl CASCADE;
+DROP TABLE vis_test;
+DROP TABLE invis_test;
+
 -- Failure for unauthorized user
 CREATE ROLE regress_reindexuser NOLOGIN;
 SET SESSION ROLE regress_reindexuser;
-- 
2.39.5 (Apple Git-154)

#72jian he
jian.universality@gmail.com
In reply to: Shayon Mukherjee (#71)
1 attachment(s)
Re: Proposal to Enable/Disable Index using ALTER INDEX (with patch)

hi.
```
drop table if exists idxpart;
create table idxpart (a int, b int, c text) partition by range (a);
create table idxpart1 (like idxpart);
alter table idxpart attach partition idxpart1 for values from (0) to (10);

create index idxpart_c on only idxpart (c) invisible;
create index idxpart1_c on idxpart1 (c);

alter index idxpart_c attach partition idxpart1_c;
```
In this case, should ALTER INDEX ATTACH PARTITION change the attached
partition(idxpart1_c)'s "visible" status?

attached is a minor patch about indentation change and meson.build change.

Attachments:

v11-0001-minor-indentation-changes.no-cfbotapplication/octet-stream; name=v11-0001-minor-indentation-changes.no-cfbotDownload
From 9d8a2e41c39d5d8e91c9eb8262f8bf5250930f0f Mon Sep 17 00:00:00 2001
From: jian he <jian.universality@gmail.com>
Date: Wed, 5 Feb 2025 19:56:09 +0800
Subject: [PATCH v11 1/1] minor indentation changes

---
 src/backend/parser/gram.y                     | 4 ++--
 src/backend/utils/adt/ruleutils.c             | 2 +-
 src/test/modules/test_ddl_deparse/meson.build | 1 +
 3 files changed, 4 insertions(+), 3 deletions(-)

diff --git a/src/backend/parser/gram.y b/src/backend/parser/gram.y
index 1f9a79dfd58..88b98c0022b 100644
--- a/src/backend/parser/gram.y
+++ b/src/backend/parser/gram.y
@@ -8268,7 +8268,7 @@ opt_unique:
 opt_index_visibility:
 			VISIBLE                       { $$ = true; }
 			| INVISIBLE                   { $$ = false; }
-			| /*EMPTY*/                 	{ $$ = true; }
+			| /*EMPTY*/                   { $$ = true; }
 		;
 
 access_method_clause:
@@ -18033,7 +18033,7 @@ unreserved_keyword:
 			| VERSION_P
 			| VIEW
 			| VIEWS
-			|	VISIBLE
+			| VISIBLE
 			| VOLATILE
 			| WHITESPACE_P
 			| WITHIN
diff --git a/src/backend/utils/adt/ruleutils.c b/src/backend/utils/adt/ruleutils.c
index a46780de877..2e930d51251 100644
--- a/src/backend/utils/adt/ruleutils.c
+++ b/src/backend/utils/adt/ruleutils.c
@@ -1565,7 +1565,7 @@ pg_get_indexdef_worker(Oid indexrelid, int colno,
 
 		/* Add INVISIBLE clause if the index is invisible */
 		if (!idxrec->indisvisible)
-				appendStringInfoString(&buf, " INVISIBLE");
+			appendStringInfoString(&buf, " INVISIBLE");
 	}
 
 	/* Clean up */
diff --git a/src/test/modules/test_ddl_deparse/meson.build b/src/test/modules/test_ddl_deparse/meson.build
index bff65ba6333..6654b5e46df 100644
--- a/src/test/modules/test_ddl_deparse/meson.build
+++ b/src/test/modules/test_ddl_deparse/meson.build
@@ -48,6 +48,7 @@ tests += {
       'opfamily',
       'defprivs',
       'matviews',
+      'alter_index',
     ],
   },
 }
-- 
2.34.1

#73Shayon Mukherjee
shayonj@gmail.com
In reply to: jian he (#72)
1 attachment(s)
Re: Proposal to Enable/Disable Index using ALTER INDEX (with patch)

On Sat, Feb 8, 2025 at 12:41 AM jian he <jian.universality@gmail.com> wrote:

hi.
```
drop table if exists idxpart;
create table idxpart (a int, b int, c text) partition by range (a);
create table idxpart1 (like idxpart);
alter table idxpart attach partition idxpart1 for values from (0) to (10);

create index idxpart_c on only idxpart (c) invisible;
create index idxpart1_c on idxpart1 (c);

alter index idxpart_c attach partition idxpart1_c;
```
In this case, should ALTER INDEX ATTACH PARTITION change the attached
partition(idxpart1_c)'s "visible" status?

Hi,
That is a great question and I have really gone back and forth on this one
and here's my reasoning so far

1. When you don't use ONLY:
- The index of child table inherits the visibility of the parent table's
index
- This applies whether the parent index is set as INVISIBLE or VISIBLE
- This automatic inheritance is expected behavior and feels natural

2. When you use ONLY:
- You as a user/developer are explicitly taking control of index
management
- Creating an index for parent as INVISIBLE and another for child as
VISIBLE represents conscious, deliberate choices
- When attaching these indexes, it makes sense to respect these explicit
visibility settings
- Silently overriding the child index's visibility could violate the
Principle of Least Surprise
- Lastly, this model also allows more granular control over index
visibility for each partition

I am not strongly tied to either of these options and very much open to
changing my mind. Also happy to try and document this for more clarity.

I have rebased the patch on top of master (resolving some merge conflicts),
along with the meson changes (thank you for that).

Thanks,
Shayon

Attachments:

v12-0001-Introduce-the-ability-to-set-index-visibility-us.patchapplication/octet-stream; name=v12-0001-Introduce-the-ability-to-set-index-visibility-us.patchDownload
From f59758a297a3e842c7b88d8a06c3a4afa8aaa720 Mon Sep 17 00:00:00 2001
From: Shayon Mukherjee <shayonj@gmail.com>
Date: Sun, 12 Jan 2025 14:34:48 -0500
Subject: [PATCH v12] Introduce the ability to set index visibility using ALTER
 INDEX

This patch introduces index visibility control using ALTER INDEX and CREATE INDEX
commands.

Original motivation for the problem and proposal for a patch
can be found at [1].

This patch passes all the existing specs and the newly added regression tests. The patch
is ready for review and test. It compiles, so the patch can be applied for testing as well.

Note: The patch has gone through a few iterations. Earlier versions of the patch had the ENABLE/DISABLE grammar.
The current version has the VISIBLE/INVISIBLE grammar. So, you will the local variable names using the new grammar accordingly.

Implementation details:

- New Grammar:
  * ALTER INDEX ... VISIBLE/INVISIBLE
  * CREATE INDEX ... INVISIBLE

- Default state is visible. Indexes are only invisible when explicitly
  instructed via CREATE INDEX ... INVISIBLE or ALTER INDEX ... INVISIBLE.

- Primary Key and Unique constraint indexes are always visible. The
  VISIBLE/INVISIBLE grammar is supported for these types of indexes and they can
  be made invisible via ALTER INDEX ... INVISIBLE.

- ALTER INDEX ... VISIBLE/INVISIBLE performs update on the relevant row in pg_index
  catalog

- pg_get_indexdef() supports the new functionality and grammar. This change is
  reflected in \d output for tables and pg_dump. We show the INVISIBLE syntax accordingly.

- Added force_invisible_index GUC parameter that forces the planner to use invisible
  indexes. This is useful for testing and validating index behavior without changing
  their visibility state. Based on feedback from Sami S [2]

- Updated create_index.sql regression test to cover the new grammar and verify
  that invisible indexes are not used in queries. The test covers:

  - Basic single-column and multi-column indexes
  - Partial indexes
  - Expression indexes
  - Join indexes
  - GIN and GiST indexes
  - Covering indexes
  - Range indexes
  - Unique indexes and constraints

- Adds a new indisvisible attribute to the IndexOptInfo structure.

- Modifies get_relation_info in plancat.c to skip invisible indexes entirely, thus reducing the number of places we need to check if an index is invisible or not. Inspired by the conversations start at [3].
  - I chose to modify the logic within get_relation_info as compared to, say, reducing the cost to make the planner not consider an index during planning, mostly to keep the number of changes being introduced to a minimum and also the logic itself being self-contained and easier to understand perhaps (?).

- No changes are made to stop the index from getting maintained. This way we ensure no
  data loss or corruption when index is made visible again.

- TOAST indexes are supported and visible by default as well.

- REINDEX CONCURRENTLY is supported as well and existing state of pg_index.indisvisible
  is carried over accordingly.

- See the changes in create_index.sql to get an idea of the grammar and sql statements.

- See the changes in create_index.out to get an idea of the catalogue states and EXPLAIN
  output to see when an index is getting used or isn't (when invisible).

- Incorporated DavidR's feedback from [4] around documentation and also you will see that by skipping invisible indexes entirely from get_relation_info in plancat.c (as mentioned above), we address the other mentioned issues as well.

- Lastly, protects against the case where indcheckxmin is true by raising ERRCODE_OBJECT_NOT_IN_PREREQUISITE_STATE.

Looking forward to any and all feedback on this patch, including but not limited to code quality, tests, fundamental logic.

[1] https://www.postgresql.org/message-id/CANqtF-oXKe0M%3D0QOih6H%2BsZRjE2BWAbkW_1%2B9nMEAMLxUJg5jA%40mail.gmail.com
[2] https://www.postgresql.org/message-id/CAA5RZ0udzydObMDi65C59-oq54B9ZmjSZ1wVH3h%2Bv4XiVm6QDA%40mail.gmail.com
[3] https://www.postgresql.org/message-id/3465209.1727202064%40sss.pgh.pa.us
[4] https://www.postgresql.org/message-id/CAApHDvpUNu%3DiVcdJ74sypvgeaCF%2Btfpyb8VRhZaF7DTd1xVr7g%40mail.gmail.com
---
 doc/src/sgml/catalogs.sgml                    |  11 +
 doc/src/sgml/config.sgml                      |  16 +
 doc/src/sgml/ref/alter_index.sgml             |  38 +
 doc/src/sgml/ref/create_index.sgml            |  29 +
 src/backend/bootstrap/bootparse.y             |   2 +
 src/backend/catalog/index.c                   |  31 +-
 src/backend/catalog/toasting.c                |   2 +-
 src/backend/commands/indexcmds.c              |   4 +
 src/backend/commands/tablecmds.c              |  92 +-
 src/backend/optimizer/util/plancat.c          |  31 +-
 src/backend/parser/gram.y                     |  56 +-
 src/backend/parser/parse_utilcmd.c            |   3 +
 src/backend/utils/adt/ruleutils.c             |   4 +
 src/backend/utils/cache/relcache.c            |   1 +
 src/backend/utils/misc/guc_tables.c           |  11 +
 src/backend/utils/misc/postgresql.conf.sample |   1 +
 src/bin/pg_dump/pg_dump.c                     |  20 +-
 src/bin/pg_dump/pg_dump.h                     |   2 +
 src/bin/pg_dump/t/002_pg_dump.pl              |  29 +
 src/bin/psql/describe.c                       |  15 +-
 src/bin/psql/tab-complete.in.c                |   3 +-
 src/include/catalog/index.h                   |   2 +-
 src/include/catalog/pg_index.h                |   1 +
 src/include/nodes/parsenodes.h                |   3 +
 src/include/optimizer/optimizer.h             |   5 +
 src/include/parser/kwlist.h                   |   2 +
 src/include/utils/guc_hooks.h                 |   1 +
 src/test/modules/test_ddl_deparse/Makefile    |   3 +-
 .../test_ddl_deparse/expected/alter_index.out |  29 +
 src/test/modules/test_ddl_deparse/meson.build |   1 +
 .../test_ddl_deparse/sql/alter_index.sql      |  18 +
 .../test_ddl_deparse/test_ddl_deparse.c       |   6 +
 src/test/regress/expected/create_index.out    | 795 ++++++++++++++++++
 src/test/regress/sql/create_index.sql         | 321 +++++++
 34 files changed, 1562 insertions(+), 26 deletions(-)
 create mode 100644 src/test/modules/test_ddl_deparse/expected/alter_index.out
 create mode 100644 src/test/modules/test_ddl_deparse/sql/alter_index.sql

diff --git a/doc/src/sgml/catalogs.sgml b/doc/src/sgml/catalogs.sgml
index ee59a7e15d..8435b7c782 100644
--- a/doc/src/sgml/catalogs.sgml
+++ b/doc/src/sgml/catalogs.sgml
@@ -4597,6 +4597,17 @@ SCRAM-SHA-256$<replaceable>&lt;iteration count&gt;</replaceable>:<replaceable>&l
        partial index.
       </para></entry>
      </row>
+
+     <row>
+      <entry role="catalog_table_entry"><para role="column_definition">
+       <structfield>indisvisible</structfield> <type>bool</type>
+      </para>
+      <para>
+       If true, the index is currently visible to the planner and may be used for queries.
+       If false, the index is invisible and may not be used for queries,
+       but is still updated when the table is modified. Default is true.
+      </para></entry>
+     </row>
     </tbody>
    </tgroup>
   </table>
diff --git a/doc/src/sgml/config.sgml b/doc/src/sgml/config.sgml
index 007746a442..146af59e31 100644
--- a/doc/src/sgml/config.sgml
+++ b/doc/src/sgml/config.sgml
@@ -5677,6 +5677,22 @@ ANY <replaceable class="parameter">num_sync</replaceable> ( <replaceable class="
       </listitem>
      </varlistentry>
 
+     <varlistentry id="guc-force-invisible-index" xreflabel="use_invisible_index">
+      <term><varname>use_invisible_index</varname> (<type>boolean</type>)
+      <indexterm>
+       <primary><varname>use_invisible_index</varname> configuration parameter</primary>
+      </indexterm>
+      </term>
+      <listitem>
+       <para>
+        Forces the query planner to consider indexes that have been marked as invisible using
+        <command>ALTER INDEX ... INVISIBLE</command>. This parameter is useful for selective
+        use of invisible indexes in specific application contexts. The default
+        is <literal>off</literal>.
+       </para>
+      </listitem>
+     </varlistentry>
+
      </variablelist>
      </sect2>
      <sect2 id="runtime-config-query-constants">
diff --git a/doc/src/sgml/ref/alter_index.sgml b/doc/src/sgml/ref/alter_index.sgml
index 1d42d05d85..d26e7761c1 100644
--- a/doc/src/sgml/ref/alter_index.sgml
+++ b/doc/src/sgml/ref/alter_index.sgml
@@ -31,6 +31,7 @@ ALTER INDEX [ IF EXISTS ] <replaceable class="parameter">name</replaceable> ALTE
     SET STATISTICS <replaceable class="parameter">integer</replaceable>
 ALTER INDEX ALL IN TABLESPACE <replaceable class="parameter">name</replaceable> [ OWNED BY <replaceable class="parameter">role_name</replaceable> [, ... ] ]
     SET TABLESPACE <replaceable class="parameter">new_tablespace</replaceable> [ NOWAIT ]
+ALTER INDEX [ IF EXISTS ] <replaceable class="parameter">name</replaceable> { VISIBLE | INVISIBLE }
 </synopsis>
  </refsynopsisdiv>
 
@@ -159,6 +160,29 @@ ALTER INDEX ALL IN TABLESPACE <replaceable class="parameter">name</replaceable>
     </listitem>
    </varlistentry>
 
+   <varlistentry>
+    <term><literal>VISIBLE</literal></term>
+    <listitem>
+     <para>
+      Make the specified index visible. The index will be used for query planning.
+     </para>
+    </listitem>
+   </varlistentry>
+
+   <varlistentry>
+    <term><literal>INVISIBLE</literal></term>
+    <listitem>
+     <para>
+      Make the specified index invisible. The index will not be used for queries.
+      This can be useful for testing query performance with and without specific
+      indexes. If performance degrades after making an index invisible, it can be easily
+      be made visible using <literal>VISIBLE</literal>. Before making an index invisible, it's recommended
+      to check <structname>pg_stat_user_indexes</structname>.<structfield>idx_scan</structfield>
+      to identify potentially unused indexes.
+     </para>
+    </listitem>
+   </varlistentry>
+
   </variablelist>
   </para>
 
@@ -301,6 +325,20 @@ CREATE INDEX coord_idx ON measured (x, y, (z + t));
 ALTER INDEX coord_idx ALTER COLUMN 3 SET STATISTICS 1000;
 </programlisting></para>
 
+  <para>
+   To make an index visible:
+<programlisting>
+ALTER INDEX idx_name VISIBLE;
+</programlisting>
+  </para>
+
+  <para>
+   To make an index invisible:
+<programlisting>
+ALTER INDEX idx_name INVISIBLE;
+</programlisting>
+  </para>
+
  </refsect1>
 
  <refsect1>
diff --git a/doc/src/sgml/ref/create_index.sgml b/doc/src/sgml/ref/create_index.sgml
index 208389e800..90d7d90a2b 100644
--- a/doc/src/sgml/ref/create_index.sgml
+++ b/doc/src/sgml/ref/create_index.sgml
@@ -28,6 +28,7 @@ CREATE [ UNIQUE ] INDEX [ CONCURRENTLY ] [ [ IF NOT EXISTS ] <replaceable class=
     [ WITH ( <replaceable class="parameter">storage_parameter</replaceable> [= <replaceable class="parameter">value</replaceable>] [, ... ] ) ]
     [ TABLESPACE <replaceable class="parameter">tablespace_name</replaceable> ]
     [ WHERE <replaceable class="parameter">predicate</replaceable> ]
+    [ INVISIBLE ]
 </synopsis>
  </refsynopsisdiv>
 
@@ -380,6 +381,19 @@ CREATE [ UNIQUE ] INDEX [ CONCURRENTLY ] [ [ IF NOT EXISTS ] <replaceable class=
       </listitem>
      </varlistentry>
 
+    <varlistentry>
+      <term><literal>INVISIBLE</literal></term>
+      <listitem>
+       <para>
+        Creates the index in an invisible state (default visible). An invisible index is
+        not used by the query planner for queries, but it is still maintained
+        when the underlying table data changes. This can be useful when you want to create
+        an index without immediately impacting query planning, allowing you to make it
+        visible later at a more convenient time. The index can be made visible later
+        using <command>ALTER INDEX ... VISIBLE</command>.
+       </para>
+      </listitem>
+     </varlistentry>
     </variablelist>
 
   <refsect2 id="sql-createindex-storage-parameters" xreflabel="Index Storage Parameters">
@@ -701,6 +715,14 @@ Indexes:
     partitioned index is a metadata only operation.
    </para>
 
+  <para>
+   When creating an index with the <literal>INVISIBLE</literal> option, the index
+   will be created but not used for query planning. This can be useful for
+   preparing an index in advance of its use, or for testing purposes. The index
+   will still be maintained as the table is modified, so it can be made visible
+   later without needing to be rebuilt. By default all new indexes are visible.
+  </para>
+
   </refsect2>
  </refsect1>
 
@@ -980,6 +1002,13 @@ SELECT * FROM points
 CREATE INDEX CONCURRENTLY sales_quantity_index ON sales_table (quantity);
 </programlisting></para>
 
+  <para>
+   To create an index on the table <literal>test_table</literal> with the default
+   name, but have it initially invisible:
+<programlisting>
+CREATE INDEX ON test_table (col1) INVISIBLE;
+</programlisting>
+  </para>
  </refsect1>
 
  <refsect1>
diff --git a/src/backend/bootstrap/bootparse.y b/src/backend/bootstrap/bootparse.y
index 9833f52c1b..ea21511a20 100644
--- a/src/backend/bootstrap/bootparse.y
+++ b/src/backend/bootstrap/bootparse.y
@@ -303,6 +303,7 @@ Boot_DeclareIndexStmt:
 					stmt->concurrent = false;
 					stmt->if_not_exists = false;
 					stmt->reset_default_tblspc = false;
+					stmt->isvisible = true;
 
 					/* locks and races need not concern us in bootstrap mode */
 					relationId = RangeVarGetRelid(stmt->relation, NoLock,
@@ -356,6 +357,7 @@ Boot_DeclareUniqueIndexStmt:
 					stmt->concurrent = false;
 					stmt->if_not_exists = false;
 					stmt->reset_default_tblspc = false;
+					stmt->isvisible = true;
 
 					/* locks and races need not concern us in bootstrap mode */
 					relationId = RangeVarGetRelid(stmt->relation, NoLock,
diff --git a/src/backend/catalog/index.c b/src/backend/catalog/index.c
index f37b990c81..3fbc280c1a 100644
--- a/src/backend/catalog/index.c
+++ b/src/backend/catalog/index.c
@@ -118,7 +118,8 @@ static void UpdateIndexRelation(Oid indexoid, Oid heapoid,
 								bool isexclusion,
 								bool immediate,
 								bool isvalid,
-								bool isready);
+								bool isready,
+								bool isvisible);
 static void index_update_stats(Relation rel,
 							   bool hasindex,
 							   double reltuples);
@@ -570,7 +571,8 @@ UpdateIndexRelation(Oid indexoid,
 					bool isexclusion,
 					bool immediate,
 					bool isvalid,
-					bool isready)
+					bool isready,
+					bool isvisible)
 {
 	int2vector *indkey;
 	oidvector  *indcollation;
@@ -648,6 +650,7 @@ UpdateIndexRelation(Oid indexoid,
 	values[Anum_pg_index_indisready - 1] = BoolGetDatum(isready);
 	values[Anum_pg_index_indislive - 1] = BoolGetDatum(true);
 	values[Anum_pg_index_indisreplident - 1] = BoolGetDatum(false);
+	values[Anum_pg_index_indisvisible - 1] = BoolGetDatum(isvisible);
 	values[Anum_pg_index_indkey - 1] = PointerGetDatum(indkey);
 	values[Anum_pg_index_indcollation - 1] = PointerGetDatum(indcollation);
 	values[Anum_pg_index_indclass - 1] = PointerGetDatum(indclass);
@@ -713,6 +716,8 @@ UpdateIndexRelation(Oid indexoid,
  *			already exists.
  *		INDEX_CREATE_PARTITIONED:
  *			create a partitioned index (table must be partitioned)
+ *		INDEX_CREATE_VISIBLE:
+ *			create the index as visible to query planner
  * constr_flags: flags passed to index_constraint_create
  *		(only if INDEX_CREATE_ADD_CONSTRAINT is set)
  * allow_system_table_mods: allow table to be a system catalog
@@ -758,6 +763,7 @@ index_create(Relation heapRelation,
 	bool		invalid = (flags & INDEX_CREATE_INVALID) != 0;
 	bool		concurrent = (flags & INDEX_CREATE_CONCURRENT) != 0;
 	bool		partitioned = (flags & INDEX_CREATE_PARTITIONED) != 0;
+	bool 		isvisible  = (flags & INDEX_CREATE_VISIBLE) != 0;
 	char		relkind;
 	TransactionId relfrozenxid;
 	MultiXactId relminmxid;
@@ -1041,13 +1047,15 @@ index_create(Relation heapRelation,
 	 *	  (Or, could define a rule to maintain the predicate) --Nels, Feb '92
 	 * ----------------
 	 */
+
 	UpdateIndexRelation(indexRelationId, heapRelationId, parentIndexRelid,
 						indexInfo,
 						collationIds, opclassIds, coloptions,
 						isprimary, is_exclusion,
 						(constr_flags & INDEX_CONSTR_CREATE_DEFERRABLE) == 0,
 						!concurrent && !invalid,
-						!concurrent);
+						!concurrent,
+						isvisible);
 
 	/*
 	 * Register relcache invalidation on the indexes' heap relation, to
@@ -1316,6 +1324,8 @@ index_concurrently_create_copy(Relation heapRelation, Oid oldIndexId,
 	List	   *indexColNames = NIL;
 	List	   *indexExprs = NIL;
 	List	   *indexPreds = NIL;
+	Form_pg_index indexForm;
+	bits16 	 createFlags;
 
 	indexRelation = index_open(oldIndexId, RowExclusiveLock);
 
@@ -1343,6 +1353,9 @@ index_concurrently_create_copy(Relation heapRelation, Oid oldIndexId,
 											Anum_pg_index_indoption);
 	indcoloptions = (int2vector *) DatumGetPointer(colOptionDatum);
 
+	/* Get the visibility state of the original index */
+	indexForm = (Form_pg_index) GETSTRUCT(indexTuple);
+
 	/* Fetch reloptions of index if any */
 	classTuple = SearchSysCache1(RELOID, ObjectIdGetDatum(oldIndexId));
 	if (!HeapTupleIsValid(classTuple))
@@ -1434,6 +1447,16 @@ index_concurrently_create_copy(Relation heapRelation, Oid oldIndexId,
 		stattargets[i].isnull = isnull;
 	}
 
+	/*
+	* Determine the create flags for the new index.
+	* We always use SKIP_BUILD and CONCURRENT for concurrent reindexing.
+	* If the original index was visible, we also set the VISIBLE flag
+	* to maintain the same state in the new index.
+	*/
+	createFlags = INDEX_CREATE_SKIP_BUILD | INDEX_CREATE_CONCURRENT;
+	if (indexForm->indisvisible)
+		createFlags |= INDEX_CREATE_VISIBLE;
+
 	/*
 	 * Now create the new index.
 	 *
@@ -1457,7 +1480,7 @@ index_concurrently_create_copy(Relation heapRelation, Oid oldIndexId,
 							  indcoloptions->values,
 							  stattargets,
 							  reloptionsDatum,
-							  INDEX_CREATE_SKIP_BUILD | INDEX_CREATE_CONCURRENT,
+							  createFlags,
 							  0,
 							  true, /* allow table to be a system catalog? */
 							  false,	/* is_internal? */
diff --git a/src/backend/catalog/toasting.c b/src/backend/catalog/toasting.c
index 874a8fc89a..7721d16fd3 100644
--- a/src/backend/catalog/toasting.c
+++ b/src/backend/catalog/toasting.c
@@ -325,7 +325,7 @@ create_toast_table(Relation rel, Oid toastOid, Oid toastIndexOid,
 				 BTREE_AM_OID,
 				 rel->rd_rel->reltablespace,
 				 collationIds, opclassIds, NULL, coloptions, NULL, (Datum) 0,
-				 INDEX_CREATE_IS_PRIMARY, 0, true, true, NULL);
+				 INDEX_CREATE_IS_PRIMARY | INDEX_CREATE_VISIBLE, 0, true, true, NULL);
 
 	table_close(toast_rel, NoLock);
 
diff --git a/src/backend/commands/indexcmds.c b/src/backend/commands/indexcmds.c
index c92f5620ec..d35b6677da 100644
--- a/src/backend/commands/indexcmds.c
+++ b/src/backend/commands/indexcmds.c
@@ -1228,6 +1228,10 @@ DefineIndex(Oid tableId,
 		flags |= INDEX_CREATE_PARTITIONED;
 	if (stmt->primary)
 		flags |= INDEX_CREATE_IS_PRIMARY;
+   if (stmt->isvisible)
+		flags |= INDEX_CREATE_VISIBLE;
+   else
+		flags &= ~INDEX_CREATE_VISIBLE;
 
 	/*
 	 * If the table is partitioned, and recursion was declined but partitions
diff --git a/src/backend/commands/tablecmds.c b/src/backend/commands/tablecmds.c
index ce7d115667..9fbe07b8d6 100644
--- a/src/backend/commands/tablecmds.c
+++ b/src/backend/commands/tablecmds.c
@@ -697,7 +697,8 @@ static List *GetParentedForeignKeyRefs(Relation partition);
 static void ATDetachCheckNoForeignKeyRefs(Relation partition);
 static char GetAttributeCompression(Oid atttypid, const char *compression);
 static char GetAttributeStorage(Oid atttypid, const char *storagemode);
-
+static void ATExecSetIndexVisibility(Relation rel, bool visible);
+static bool GetIndexVisibility(Oid indexOid);
 
 /* ----------------------------------------------------------------
  *		DefineRelation
@@ -4804,6 +4805,11 @@ AlterTableGetLockLevel(List *cmds)
 				cmd_lockmode = ShareUpdateExclusiveLock;
 				break;
 
+			case AT_SetIndexVisible:
+			case AT_SetIndexInvisible:
+				cmd_lockmode = ShareUpdateExclusiveLock;
+				break;
+
 			default:			/* oops */
 				elog(ERROR, "unrecognized alter table type: %d",
 					 (int) cmd->subtype);
@@ -5239,6 +5245,13 @@ ATPrepCmd(List **wqueue, Relation rel, AlterTableCmd *cmd,
 			/* No command-specific prep needed */
 			pass = AT_PASS_MISC;
 			break;
+		case AT_SetIndexVisible:
+		case AT_SetIndexInvisible:
+			ATSimplePermissions(cmd->subtype, rel, ATT_INDEX | ATT_PARTITIONED_INDEX);
+			ATSimpleRecursion(wqueue, rel, cmd, true, lockmode, context);
+			/* No command-specific prep needed */
+			pass = AT_PASS_MISC;
+			break;
 		default:				/* oops */
 			elog(ERROR, "unrecognized alter table type: %d",
 				 (int) cmd->subtype);
@@ -5635,6 +5648,12 @@ ATExecCmd(List **wqueue, AlteredTableInfo *tab,
 		case AT_DetachPartitionFinalize:
 			address = ATExecDetachPartitionFinalize(rel, ((PartitionCmd *) cmd->def)->name);
 			break;
+		case AT_SetIndexVisible:
+				ATExecSetIndexVisibility(rel, true);
+				break;
+		case AT_SetIndexInvisible:
+				ATExecSetIndexVisibility(rel, false);
+				break;
 		default:				/* oops */
 			elog(ERROR, "unrecognized alter table type: %d",
 				 (int) cmd->subtype);
@@ -6529,6 +6548,8 @@ alter_table_type_to_string(AlterTableType cmdtype)
 			return "DROP COLUMN";
 		case AT_AddIndex:
 		case AT_ReAddIndex:
+		case AT_SetIndexVisible:
+		case AT_SetIndexInvisible:
 			return NULL;		/* not real grammar */
 		case AT_AddConstraint:
 		case AT_ReAddConstraint:
@@ -14754,6 +14775,8 @@ ATPostAlterTypeParse(Oid oldId, Oid oldRelId, Oid refRelId, char *cmd,
 			stmt->reset_default_tblspc = true;
 			/* keep the index's comment */
 			stmt->idxcomment = GetComment(oldId, RelationRelationId, 0);
+			/* preserve the index's visibility status */
+			stmt->isvisible = GetIndexVisibility(oldId);
 
 			newcmd = makeNode(AlterTableCmd);
 			newcmd->subtype = AT_ReAddIndex;
@@ -14784,6 +14807,8 @@ ATPostAlterTypeParse(Oid oldId, Oid oldRelId, Oid refRelId, char *cmd,
 					indstmt->idxcomment = GetComment(indoid,
 													 RelationRelationId, 0);
 					indstmt->reset_default_tblspc = true;
+					/* preserve the index's visibility status */
+					indstmt->isvisible = GetIndexVisibility(indoid);
 
 					cmd->subtype = AT_ReAddIndex;
 					tab->subcmds[AT_PASS_OLD_INDEX] =
@@ -21128,3 +21153,68 @@ GetAttributeStorage(Oid atttypid, const char *storagemode)
 
 	return cstorage;
 }
+
+/*
+ * ATExecSetIndexVisibility
+ * Performs a catalog update to mark an index as visible or invisible in pg_index.
+ */
+static void
+ATExecSetIndexVisibility(Relation rel, bool visible)
+{
+	Oid			indexOid = RelationGetRelid(rel);
+	Oid			heapOid;
+	Relation	pg_index;
+	Relation	heapRel;
+	HeapTuple	indexTuple;
+	Form_pg_index	indexForm;
+
+	heapOid = IndexGetRelation(indexOid, false);
+	heapRel = table_open(heapOid, AccessShareLock);
+	pg_index = table_open(IndexRelationId, RowExclusiveLock);
+
+	indexTuple = SearchSysCacheCopy1(INDEXRELID, ObjectIdGetDatum(indexOid));
+	if (!HeapTupleIsValid(indexTuple))
+		elog(ERROR, "cache lookup failed for index %u", indexOid);
+
+	indexForm = (Form_pg_index) GETSTRUCT(indexTuple);
+	if (indexForm->indcheckxmin)
+		ereport(ERROR,
+				errcode(ERRCODE_OBJECT_NOT_IN_PREREQUISITE_STATE),
+				errmsg("cannot update index visibility while indcheckxmin is true"),
+				errhint("Wait for all transactions that might see inconsistent HOT chains to complete"));
+
+	if (indexForm->indisvisible != visible)
+	{
+		indexForm->indisvisible = visible;
+		CatalogTupleUpdate(pg_index, &indexTuple->t_self, indexTuple);
+
+		CacheInvalidateRelcache(heapRel);
+		InvokeObjectPostAlterHook(IndexRelationId, indexOid, 0);
+		CommandCounterIncrement();
+	}
+
+	heap_freetuple(indexTuple);
+	table_close(pg_index, RowExclusiveLock);
+	table_close(heapRel, AccessShareLock);
+}
+
+/*
+* Get index visibility status from pg_index
+*/
+static bool
+GetIndexVisibility(Oid indexOid)
+{
+	HeapTuple   indexTuple;
+	Form_pg_index indexForm;
+	bool        isvisible;
+
+	indexTuple = SearchSysCache1(INDEXRELID, ObjectIdGetDatum(indexOid));
+	if (!HeapTupleIsValid(indexTuple))
+		elog(ERROR, "cache lookup failed for index %u", indexOid);
+
+	indexForm = (Form_pg_index) GETSTRUCT(indexTuple);
+	isvisible = indexForm->indisvisible;
+	ReleaseSysCache(indexTuple);
+
+	return isvisible;
+}
diff --git a/src/backend/optimizer/util/plancat.c b/src/backend/optimizer/util/plancat.c
index 71abb01f65..0b0682b505 100644
--- a/src/backend/optimizer/util/plancat.c
+++ b/src/backend/optimizer/util/plancat.c
@@ -47,7 +47,9 @@
 #include "storage/bufmgr.h"
 #include "tcop/tcopprot.h"
 #include "utils/builtins.h"
+#include "utils/guc_hooks.h"
 #include "utils/lsyscache.h"
+#include "utils/plancache.h"
 #include "utils/partcache.h"
 #include "utils/rel.h"
 #include "utils/snapmgr.h"
@@ -55,6 +57,7 @@
 
 /* GUC parameter */
 int			constraint_exclusion = CONSTRAINT_EXCLUSION_PARTITION;
+bool		use_invisible_index = false;
 
 /* Hook for plugins to get control in get_relation_info() */
 get_relation_info_hook_type get_relation_info_hook = NULL;
@@ -254,13 +257,12 @@ get_relation_info(PlannerInfo *root, Oid relationObjectId, bool inhparent,
 			index = indexRelation->rd_index;
 
 			/*
-			 * Ignore invalid indexes, since they can't safely be used for
-			 * queries.  Note that this is OK because the data structure we
-			 * are constructing is only used by the planner --- the executor
-			 * still needs to insert into "invalid" indexes, if they're marked
-			 * indisready.
-			 */
-			if (!index->indisvalid)
+			 * Skip invalid indexes, and invisible indexes unless use_invisible_index
+			 * is set. This is OK because the data structure we are constructing is
+			 * only used by the planner - the executor still needs to insert into
+			 * these indexes if they're marked indisready.
+			*/
+			if (!index->indisvalid || (!index->indisvisible && !use_invisible_index))
 			{
 				index_close(indexRelation, NoLock);
 				continue;
@@ -2610,3 +2612,18 @@ set_baserel_partition_constraint(Relation relation, RelOptInfo *rel)
 		rel->partition_qual = partconstr;
 	}
 }
+
+/*
+ * assign_use_invisible_index
+ * GUC assign_hook for "use_invisible_index" GUC variable.
+ * Resets the plan cache when the value changes.
+ */
+void
+assign_use_invisible_index(bool newval, void *extra)
+{
+	if (use_invisible_index != newval)
+	{
+		use_invisible_index = newval;
+		ResetPlanCache();
+	}
+}
diff --git a/src/backend/parser/gram.y b/src/backend/parser/gram.y
index 7d99c9355c..7ec78c45a8 100644
--- a/src/backend/parser/gram.y
+++ b/src/backend/parser/gram.y
@@ -324,7 +324,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 %type <ival>	add_drop opt_asc_desc opt_nulls_order
 
 %type <node>	alter_table_cmd alter_type_cmd opt_collate_clause
-	   replica_identity partition_cmd index_partition_cmd
+	   replica_identity partition_cmd index_partition_cmd index_alter_cmd
 %type <list>	alter_table_cmds alter_type_cmds
 %type <list>    alter_identity_column_option_list
 %type <defelt>  alter_identity_column_option
@@ -491,6 +491,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 %type <boolean> opt_unique opt_verbose opt_full
 %type <boolean> opt_freeze opt_analyze opt_default
 %type <defelt>	opt_binary copy_delimiter
+%type <boolean>  opt_index_visibility
 
 %type <boolean> copy_from opt_program
 
@@ -733,7 +734,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 	IDENTITY_P IF_P ILIKE IMMEDIATE IMMUTABLE IMPLICIT_P IMPORT_P IN_P INCLUDE
 	INCLUDING INCREMENT INDENT INDEX INDEXES INHERIT INHERITS INITIALLY INLINE_P
 	INNER_P INOUT INPUT_P INSENSITIVE INSERT INSTEAD INT_P INTEGER
-	INTERSECT INTERVAL INTO INVOKER IS ISNULL ISOLATION
+	INTERSECT INTERVAL INTO INVISIBLE INVOKER IS ISNULL ISOLATION
 
 	JOIN JSON JSON_ARRAY JSON_ARRAYAGG JSON_EXISTS JSON_OBJECT JSON_OBJECTAGG
 	JSON_QUERY JSON_SCALAR JSON_SERIALIZE JSON_TABLE JSON_VALUE
@@ -784,7 +785,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 	UNLISTEN UNLOGGED UNTIL UPDATE USER USING
 
 	VACUUM VALID VALIDATE VALIDATOR VALUE_P VALUES VARCHAR VARIADIC VARYING
-	VERBOSE VERSION_P VIEW VIEWS VIRTUAL VOLATILE
+	VERBOSE VERSION_P VIEW VIEWS VIRTUAL VISIBLE VOLATILE
 
 	WHEN WHERE WHITESPACE_P WINDOW WITH WITHIN WITHOUT WORK WRAPPER WRITE
 
@@ -2157,6 +2158,24 @@ AlterTableStmt:
 					n->nowait = $13;
 					$$ = (Node *) n;
 				}
+		| ALTER INDEX qualified_name index_alter_cmd
+				{
+					AlterTableStmt *n = makeNode(AlterTableStmt);
+					n->relation = $3;
+					n->cmds = list_make1($4);
+					n->objtype = OBJECT_INDEX;
+					n->missing_ok = false;
+					$$ = (Node *) n;
+				}
+		| ALTER INDEX IF_P EXISTS qualified_name index_alter_cmd
+				{
+					AlterTableStmt *n = makeNode(AlterTableStmt);
+					n->relation = $5;
+					n->cmds = list_make1($6);
+					n->objtype = OBJECT_INDEX;
+					n->missing_ok = true;
+					$$ = (Node *) n;
+				}
 		|	ALTER INDEX qualified_name alter_table_cmds
 				{
 					AlterTableStmt *n = makeNode(AlterTableStmt);
@@ -2382,6 +2401,21 @@ index_partition_cmd:
 				}
 		;
 
+index_alter_cmd:
+		/* ALTER INDEX <name> VISIBLE|INVISIBLE */
+		VISIBLE
+			{
+				AlterTableCmd *n = makeNode(AlterTableCmd);
+				n->subtype = AT_SetIndexVisible;
+				$$ = (Node *) n;
+			}
+		| INVISIBLE
+			{
+				AlterTableCmd *n = makeNode(AlterTableCmd);
+				n->subtype = AT_SetIndexInvisible;
+				$$ = (Node *) n;
+			}
+		;
 alter_table_cmd:
 			/* ALTER TABLE <name> ADD <coldef> */
 			ADD_P columnDef
@@ -8167,7 +8201,7 @@ defacl_privilege_target:
 
 IndexStmt:	CREATE opt_unique INDEX opt_concurrently opt_single_name
 			ON relation_expr access_method_clause '(' index_params ')'
-			opt_include opt_unique_null_treatment opt_reloptions OptTableSpace where_clause
+			opt_include opt_unique_null_treatment opt_reloptions OptTableSpace where_clause opt_index_visibility
 				{
 					IndexStmt *n = makeNode(IndexStmt);
 
@@ -8182,6 +8216,7 @@ IndexStmt:	CREATE opt_unique INDEX opt_concurrently opt_single_name
 					n->options = $14;
 					n->tableSpace = $15;
 					n->whereClause = $16;
+					n->isvisible = $17;
 					n->excludeOpNames = NIL;
 					n->idxcomment = NULL;
 					n->indexOid = InvalidOid;
@@ -8199,7 +8234,7 @@ IndexStmt:	CREATE opt_unique INDEX opt_concurrently opt_single_name
 				}
 			| CREATE opt_unique INDEX opt_concurrently IF_P NOT EXISTS name
 			ON relation_expr access_method_clause '(' index_params ')'
-			opt_include opt_unique_null_treatment opt_reloptions OptTableSpace where_clause
+			opt_include opt_unique_null_treatment opt_reloptions OptTableSpace where_clause opt_index_visibility
 				{
 					IndexStmt *n = makeNode(IndexStmt);
 
@@ -8214,6 +8249,7 @@ IndexStmt:	CREATE opt_unique INDEX opt_concurrently opt_single_name
 					n->options = $17;
 					n->tableSpace = $18;
 					n->whereClause = $19;
+					n->isvisible = $20;
 					n->excludeOpNames = NIL;
 					n->idxcomment = NULL;
 					n->indexOid = InvalidOid;
@@ -8236,6 +8272,12 @@ opt_unique:
 			| /*EMPTY*/								{ $$ = false; }
 		;
 
+opt_index_visibility:
+			VISIBLE                       { $$ = true; }
+			| INVISIBLE                   { $$ = false; }
+			| /*EMPTY*/                   { $$ = true; }
+		;
+
 access_method_clause:
 			USING name								{ $$ = $2; }
 			| /*EMPTY*/								{ $$ = DEFAULT_INDEX_TYPE; }
@@ -17813,6 +17855,7 @@ unreserved_keyword:
 			| INSENSITIVE
 			| INSERT
 			| INSTEAD
+			| INVISIBLE
 			| INVOKER
 			| ISOLATION
 			| KEEP
@@ -17998,6 +18041,7 @@ unreserved_keyword:
 			| VIEW
 			| VIEWS
 			| VIRTUAL
+			| VISIBLE
 			| VOLATILE
 			| WHITESPACE_P
 			| WITHIN
@@ -18407,6 +18451,7 @@ bare_label_keyword:
 			| INT_P
 			| INTEGER
 			| INTERVAL
+			| INVISIBLE
 			| INVOKER
 			| IS
 			| ISOLATION
@@ -18654,6 +18699,7 @@ bare_label_keyword:
 			| VIEW
 			| VIEWS
 			| VIRTUAL
+			| VISIBLE
 			| VOLATILE
 			| WHEN
 			| WHITESPACE_P
diff --git a/src/backend/parser/parse_utilcmd.c b/src/backend/parser/parse_utilcmd.c
index abbe1bb45a..977bc38b47 100644
--- a/src/backend/parser/parse_utilcmd.c
+++ b/src/backend/parser/parse_utilcmd.c
@@ -1759,6 +1759,7 @@ generateClonedIndexStmt(RangeVar *heapRel, Relation source_idx,
 	index->concurrent = false;
 	index->if_not_exists = false;
 	index->reset_default_tblspc = false;
+	index->isvisible = idxrec->indisvisible;
 
 	/*
 	 * We don't try to preserve the name of the source index; instead, just
@@ -2380,6 +2381,8 @@ transformIndexConstraint(Constraint *constraint, CreateStmtContext *cxt)
 	index->concurrent = false;
 	index->if_not_exists = false;
 	index->reset_default_tblspc = constraint->reset_default_tblspc;
+	/* Ensure indexes for constraints are created as visible by default */
+	index->isvisible = true;
 
 	/*
 	 * If it's ALTER TABLE ADD CONSTRAINT USING INDEX, look up the index and
diff --git a/src/backend/utils/adt/ruleutils.c b/src/backend/utils/adt/ruleutils.c
index d11a8a20ee..e0cceb189e 100644
--- a/src/backend/utils/adt/ruleutils.c
+++ b/src/backend/utils/adt/ruleutils.c
@@ -1562,6 +1562,10 @@ pg_get_indexdef_worker(Oid indexrelid, int colno,
 			else
 				appendStringInfo(&buf, " WHERE %s", str);
 		}
+
+		/* Add INVISIBLE clause if the index is invisible */
+		if (!idxrec->indisvisible)
+				appendStringInfoString(&buf, " INVISIBLE");
 	}
 
 	/* Clean up */
diff --git a/src/backend/utils/cache/relcache.c b/src/backend/utils/cache/relcache.c
index 398114373e..b07387b9d2 100644
--- a/src/backend/utils/cache/relcache.c
+++ b/src/backend/utils/cache/relcache.c
@@ -2314,6 +2314,7 @@ RelationReloadIndexInfo(Relation relation)
 		relation->rd_index->indisready = index->indisready;
 		relation->rd_index->indislive = index->indislive;
 		relation->rd_index->indisreplident = index->indisreplident;
+		relation->rd_index->indisvisible = index->indisvisible;
 
 		/* Copy xmin too, as that is needed to make sense of indcheckxmin */
 		HeapTupleHeaderSetXmin(relation->rd_indextuple->t_data,
diff --git a/src/backend/utils/misc/guc_tables.c b/src/backend/utils/misc/guc_tables.c
index 03a6dd4915..af3c572e0b 100644
--- a/src/backend/utils/misc/guc_tables.c
+++ b/src/backend/utils/misc/guc_tables.c
@@ -2117,6 +2117,17 @@ struct config_bool ConfigureNamesBool[] =
 		NULL, NULL, NULL
 	},
 
+	{
+		{"use_invisible_index", PGC_USERSET, QUERY_TUNING_OTHER,
+			gettext_noop("Forces the planner to consider invisible indexes."),
+			NULL,
+			GUC_EXPLAIN
+		},
+		&use_invisible_index,
+		false,
+		NULL, assign_use_invisible_index, NULL
+	},
+
 	/* End-of-list marker */
 	{
 		{NULL, 0, 0, NULL, NULL}, NULL, false, NULL, NULL, NULL
diff --git a/src/backend/utils/misc/postgresql.conf.sample b/src/backend/utils/misc/postgresql.conf.sample
index 5362ff8051..715345892c 100644
--- a/src/backend/utils/misc/postgresql.conf.sample
+++ b/src/backend/utils/misc/postgresql.conf.sample
@@ -415,6 +415,7 @@
 #enable_tidscan = on
 #enable_group_by_reordering = on
 #enable_distinct_reordering = on
+#use_invisible_index = off		# forces planner to consider invisible indexes
 
 # - Planner Cost Constants -
 
diff --git a/src/bin/pg_dump/pg_dump.c b/src/bin/pg_dump/pg_dump.c
index afd7928717..c211f03287 100644
--- a/src/bin/pg_dump/pg_dump.c
+++ b/src/bin/pg_dump/pg_dump.c
@@ -7518,7 +7518,8 @@ getIndexes(Archive *fout, TableInfo tblinfo[], int numTables)
 				i_tablespace,
 				i_indreloptions,
 				i_indstatcols,
-				i_indstatvals;
+				i_indstatvals,
+				i_indisvisible;
 
 	/*
 	 * We want to perform just one query against pg_index.  However, we
@@ -7553,7 +7554,7 @@ getIndexes(Archive *fout, TableInfo tblinfo[], int numTables)
 						 "SELECT t.tableoid, t.oid, i.indrelid, "
 						 "t.relname AS indexname, "
 						 "pg_catalog.pg_get_indexdef(i.indexrelid) AS indexdef, "
-						 "i.indkey, i.indisclustered, "
+						 "i.indkey, i.indisclustered, i.indisvisible, "
 						 "c.contype, c.conname, "
 						 "c.condeferrable, c.condeferred, "
 						 "c.tableoid AS contableoid, "
@@ -7570,6 +7571,13 @@ getIndexes(Archive *fout, TableInfo tblinfo[], int numTables)
 		appendPQExpBufferStr(query,
 							 "false AS indisreplident, ");
 
+	if (fout->remoteVersion >= 180000)
+		appendPQExpBufferStr(query,
+							 "i.indisvisible, ");
+	else
+		appendPQExpBufferStr(query,
+							 "true AS indisvisible, ");
+
 	if (fout->remoteVersion >= 110000)
 		appendPQExpBufferStr(query,
 							 "inh.inhparent AS parentidx, "
@@ -7679,6 +7687,7 @@ getIndexes(Archive *fout, TableInfo tblinfo[], int numTables)
 	i_indreloptions = PQfnumber(res, "indreloptions");
 	i_indstatcols = PQfnumber(res, "indstatcols");
 	i_indstatvals = PQfnumber(res, "indstatvals");
+	i_indisvisible = PQfnumber(res, "indisvisible");
 
 	indxinfo = (IndxInfo *) pg_malloc(ntups * sizeof(IndxInfo));
 
@@ -7758,6 +7767,7 @@ getIndexes(Archive *fout, TableInfo tblinfo[], int numTables)
 			else
 				indexkind = RELKIND_PARTITIONED_INDEX;
 
+			indxinfo[j].indisvisible = (PQgetvalue(res, j, i_indisvisible)[0] == 't');
 			contype = *(PQgetvalue(res, j, i_contype));
 			relstats = getRelationStatistics(fout, &indxinfo[j].dobj, indexkind);
 
@@ -17813,6 +17823,12 @@ dumpConstraint(Archive *fout, const ConstraintInfo *coninfo)
 			}
 
 			appendPQExpBufferStr(q, ";\n");
+
+			if (!indxinfo->indisvisible)
+			{
+				appendPQExpBuffer(q, "ALTER INDEX %s INVISIBLE;\n",
+								  fmtQualifiedDumpable(indxinfo));
+			}
 		}
 
 		/*
diff --git a/src/bin/pg_dump/pg_dump.h b/src/bin/pg_dump/pg_dump.h
index f08f5905aa..f87d5c0f7f 100644
--- a/src/bin/pg_dump/pg_dump.h
+++ b/src/bin/pg_dump/pg_dump.h
@@ -426,6 +426,8 @@ typedef struct _indxInfo
 
 	/* if there is an associated constraint object, its dumpId: */
 	DumpId		indexconstraint;
+
+	bool			indisvisible;
 } IndxInfo;
 
 typedef struct _indexAttachInfo
diff --git a/src/bin/pg_dump/t/002_pg_dump.pl b/src/bin/pg_dump/t/002_pg_dump.pl
index 3945e4f0e2..6fcc48f5b7 100644
--- a/src/bin/pg_dump/t/002_pg_dump.pl
+++ b/src/bin/pg_dump/t/002_pg_dump.pl
@@ -2137,6 +2137,35 @@ my %tests = (
 		like => {},
 	},
 
+	'ALTER TABLE ONLY test_table ADD CONSTRAINT ... PRIMARY KEY INVISIBLE' => {
+		create_order => 97,
+		create_sql => 'CREATE TABLE dump_test.test_table_invisible (
+					   id int PRIMARY KEY
+					  );
+					  ALTER INDEX dump_test.test_table_invisible_pkey INVISIBLE;',
+		regexp => qr/^
+			\QALTER TABLE ONLY dump_test.test_table_invisible\E\n\s+
+			\QADD CONSTRAINT test_table_invisible_pkey PRIMARY KEY (id);\E\n
+			\QALTER INDEX dump_test.test_table_invisible_pkey INVISIBLE;\E
+			/xm,
+		like => { %full_runs, %dump_test_schema_runs, section_post_data => 1 },
+		unlike => { exclude_dump_test_schema => 1, only_dump_measurement => 1 },
+	},
+
+	'CREATE INDEX ... INVISIBLE' => {
+		create_order => 98,
+		create_sql => 'CREATE TABLE dump_test.test_table_mixed_indexes (
+					   id int,
+					   value int
+					  );
+					  CREATE INDEX idx_visible ON dump_test.test_table_mixed_indexes(value);
+					  CREATE UNIQUE INDEX idx_invisible ON dump_test.test_table_mixed_indexes(value) INVISIBLE;
+					  ALTER INDEX dump_test.idx_invisible INVISIBLE;',
+		regexp => qr/CREATE UNIQUE INDEX idx_invisible ON dump_test\.test_table_mixed_indexes USING btree \(value\) INVISIBLE;/m,
+		like => { %full_runs, %dump_test_schema_runs, section_post_data => 1 },
+		unlike => { exclude_dump_test_schema => 1, only_dump_measurement => 1 },
+	},
+
 	'CREATE AGGREGATE dump_test.newavg' => {
 		create_order => 25,
 		create_sql => 'CREATE AGGREGATE dump_test.newavg (
diff --git a/src/bin/psql/describe.c b/src/bin/psql/describe.c
index e6cf468ac9..7ba3932302 100644
--- a/src/bin/psql/describe.c
+++ b/src/bin/psql/describe.c
@@ -2325,6 +2325,11 @@ describeOneTableDetails(const char *schemaname,
 		else
 			appendPQExpBufferStr(&buf, "false AS indnullsnotdistinct,\n");
 
+		if (pset.sversion >= 180000)
+			appendPQExpBufferStr(&buf, "i.indisvisible,\n");
+		else
+			appendPQExpBufferStr(&buf, "true AS indisvisible,\n");
+
 		appendPQExpBuffer(&buf, "  a.amname, c2.relname, "
 						  "pg_catalog.pg_get_expr(i.indpred, i.indrelid, true)\n"
 						  "FROM pg_catalog.pg_index i, pg_catalog.pg_class c, pg_catalog.pg_class c2, pg_catalog.pg_am a\n"
@@ -2350,9 +2355,10 @@ describeOneTableDetails(const char *schemaname,
 			char	   *deferred = PQgetvalue(result, 0, 5);
 			char	   *indisreplident = PQgetvalue(result, 0, 6);
 			char	   *indnullsnotdistinct = PQgetvalue(result, 0, 7);
-			char	   *indamname = PQgetvalue(result, 0, 8);
-			char	   *indtable = PQgetvalue(result, 0, 9);
-			char	   *indpred = PQgetvalue(result, 0, 10);
+			char	   *indisvisible = PQgetvalue(result, 0, 8);
+			char	   *indamname = PQgetvalue(result, 0, 9);
+			char	   *indtable = PQgetvalue(result, 0, 10);
+			char	   *indpred = PQgetvalue(result, 0, 11);
 
 			if (strcmp(indisprimary, "t") == 0)
 				printfPQExpBuffer(&tmpbuf, _("primary key, "));
@@ -2389,6 +2395,9 @@ describeOneTableDetails(const char *schemaname,
 			if (strcmp(indisreplident, "t") == 0)
 				appendPQExpBufferStr(&tmpbuf, _(", replica identity"));
 
+			if (strcmp(indisvisible, "t") != 0)
+				appendPQExpBufferStr(&tmpbuf, _(", invisible"));
+
 			printTableAddFooter(&cont, tmpbuf.data);
 
 			/*
diff --git a/src/bin/psql/tab-complete.in.c b/src/bin/psql/tab-complete.in.c
index 8432be641a..a7c72c2ad4 100644
--- a/src/bin/psql/tab-complete.in.c
+++ b/src/bin/psql/tab-complete.in.c
@@ -2418,7 +2418,8 @@ match_previous_words(int pattern_id,
 	else if (Matches("ALTER", "INDEX", MatchAny))
 		COMPLETE_WITH("ALTER COLUMN", "OWNER TO", "RENAME TO", "SET",
 					  "RESET", "ATTACH PARTITION",
-					  "DEPENDS ON EXTENSION", "NO DEPENDS ON EXTENSION");
+					  "DEPENDS ON EXTENSION", "NO DEPENDS ON EXTENSION",
+					  "INVISIBLE", "VISIBLE");
 	else if (Matches("ALTER", "INDEX", MatchAny, "ATTACH"))
 		COMPLETE_WITH("PARTITION");
 	else if (Matches("ALTER", "INDEX", MatchAny, "ATTACH", "PARTITION"))
diff --git a/src/include/catalog/index.h b/src/include/catalog/index.h
index 4daa8bef5e..75bef5bd88 100644
--- a/src/include/catalog/index.h
+++ b/src/include/catalog/index.h
@@ -65,6 +65,7 @@ extern void index_check_primary_key(Relation heapRel,
 #define	INDEX_CREATE_IF_NOT_EXISTS			(1 << 4)
 #define	INDEX_CREATE_PARTITIONED			(1 << 5)
 #define INDEX_CREATE_INVALID				(1 << 6)
+#define INDEX_CREATE_VISIBLE				(1 << 7)
 
 extern Oid	index_create(Relation heapRelation,
 						 const char *indexRelationName,
@@ -175,7 +176,6 @@ extern void RestoreReindexState(const void *reindexstate);
 
 extern void IndexSetParentIndex(Relation partitionIdx, Oid parentOid);
 
-
 /*
  * itemptr_encode - Encode ItemPointer as int64/int8
  *
diff --git a/src/include/catalog/pg_index.h b/src/include/catalog/pg_index.h
index 4392b9d221..cf1bea9c81 100644
--- a/src/include/catalog/pg_index.h
+++ b/src/include/catalog/pg_index.h
@@ -44,6 +44,7 @@ CATALOG(pg_index,2610,IndexRelationId) BKI_SCHEMA_MACRO
 	bool		indisready;		/* is this index ready for inserts? */
 	bool		indislive;		/* is this index alive at all? */
 	bool		indisreplident; /* is this index the identity for replication? */
+	bool		indisvisible BKI_DEFAULT(t);	/* is this index visible for use by queries? */
 
 	/* variable-length fields start here, but we allow direct access to indkey */
 	int2vector	indkey BKI_FORCE_NOT_NULL;	/* column numbers of indexed cols,
diff --git a/src/include/nodes/parsenodes.h b/src/include/nodes/parsenodes.h
index 0b208f51bd..e7f5bcfc04 100644
--- a/src/include/nodes/parsenodes.h
+++ b/src/include/nodes/parsenodes.h
@@ -2467,6 +2467,8 @@ typedef enum AlterTableType
 	AT_SetIdentity,				/* SET identity column options */
 	AT_DropIdentity,			/* DROP IDENTITY */
 	AT_ReAddStatistics,			/* internal to commands/tablecmds.c */
+	AT_SetIndexVisible,			/* Set INDEX visible */
+	AT_SetIndexInvisible,		/* Set INDEX invisible */
 } AlterTableType;
 
 typedef struct AlterTableCmd	/* one subcommand of an ALTER TABLE */
@@ -3461,6 +3463,7 @@ typedef struct IndexStmt
 	bool		if_not_exists;	/* just do nothing if index already exists? */
 	bool		reset_default_tblspc;	/* reset default_tablespace prior to
 										 * executing */
+  bool		isvisible;		/* true if VISIBLE (default), false if INVISIBLE */
 } IndexStmt;
 
 /* ----------------------
diff --git a/src/include/optimizer/optimizer.h b/src/include/optimizer/optimizer.h
index 78e05d88c8..df7abcb20a 100644
--- a/src/include/optimizer/optimizer.h
+++ b/src/include/optimizer/optimizer.h
@@ -207,4 +207,9 @@ extern List *pull_var_clause(Node *node, int flags);
 extern Node *flatten_join_alias_vars(PlannerInfo *root, Query *query, Node *node);
 extern Node *flatten_group_exprs(PlannerInfo *root, Query *query, Node *node);
 
+/*
+ * GUC to tell planner to consider invisible indexes.
+ */
+extern bool use_invisible_index;
+
 #endif							/* OPTIMIZER_H */
diff --git a/src/include/parser/kwlist.h b/src/include/parser/kwlist.h
index 40cf090ce6..7f0947988b 100644
--- a/src/include/parser/kwlist.h
+++ b/src/include/parser/kwlist.h
@@ -229,6 +229,7 @@ PG_KEYWORD("integer", INTEGER, COL_NAME_KEYWORD, BARE_LABEL)
 PG_KEYWORD("intersect", INTERSECT, RESERVED_KEYWORD, AS_LABEL)
 PG_KEYWORD("interval", INTERVAL, COL_NAME_KEYWORD, BARE_LABEL)
 PG_KEYWORD("into", INTO, RESERVED_KEYWORD, AS_LABEL)
+PG_KEYWORD("invisible", INVISIBLE, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("invoker", INVOKER, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("is", IS, TYPE_FUNC_NAME_KEYWORD, BARE_LABEL)
 PG_KEYWORD("isnull", ISNULL, TYPE_FUNC_NAME_KEYWORD, AS_LABEL)
@@ -492,6 +493,7 @@ PG_KEYWORD("version", VERSION_P, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("view", VIEW, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("views", VIEWS, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("virtual", VIRTUAL, UNRESERVED_KEYWORD, BARE_LABEL)
+PG_KEYWORD("visible", VISIBLE, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("volatile", VOLATILE, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("when", WHEN, RESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("where", WHERE, RESERVED_KEYWORD, AS_LABEL)
diff --git a/src/include/utils/guc_hooks.h b/src/include/utils/guc_hooks.h
index 951451a976..a5f2355720 100644
--- a/src/include/utils/guc_hooks.h
+++ b/src/include/utils/guc_hooks.h
@@ -176,5 +176,6 @@ extern bool check_synchronized_standby_slots(char **newval, void **extra,
 extern void assign_synchronized_standby_slots(const char *newval, void *extra);
 extern bool check_idle_replication_slot_timeout(int *newval, void **extra,
 												GucSource source);
+extern void assign_use_invisible_index(bool newval, void *extra);
 
 #endif							/* GUC_HOOKS_H */
diff --git a/src/test/modules/test_ddl_deparse/Makefile b/src/test/modules/test_ddl_deparse/Makefile
index 3a57a95c84..747d8b5835 100644
--- a/src/test/modules/test_ddl_deparse/Makefile
+++ b/src/test/modules/test_ddl_deparse/Makefile
@@ -27,7 +27,8 @@ REGRESS = test_ddl_deparse \
 	alter_type_enum \
 	opfamily \
 	defprivs \
-	matviews
+	matviews \
+	alter_index
 
 EXTRA_INSTALL = contrib/pg_stat_statements
 
diff --git a/src/test/modules/test_ddl_deparse/expected/alter_index.out b/src/test/modules/test_ddl_deparse/expected/alter_index.out
new file mode 100644
index 0000000000..f502baf1c5
--- /dev/null
+++ b/src/test/modules/test_ddl_deparse/expected/alter_index.out
@@ -0,0 +1,29 @@
+-- Test index visibility commands
+CREATE TABLE visibility_test (id int);
+NOTICE:  DDL test: type simple, tag CREATE TABLE
+CREATE INDEX idx_vis ON visibility_test(id);
+NOTICE:  DDL test: type simple, tag CREATE INDEX
+ALTER INDEX idx_vis INVISIBLE;
+NOTICE:  DDL test: type alter table, tag ALTER INDEX
+NOTICE:    subcommand: type SET INVISIBLE desc <NULL>
+ALTER INDEX idx_vis VISIBLE;
+NOTICE:  DDL test: type alter table, tag ALTER INDEX
+NOTICE:    subcommand: type SET VISIBLE desc <NULL>
+ALTER INDEX idx_vis INVISIBLE;
+NOTICE:  DDL test: type alter table, tag ALTER INDEX
+NOTICE:    subcommand: type SET INVISIBLE desc <NULL>
+REINDEX INDEX idx_vis;
+NOTICE:  DDL test: type simple, tag REINDEX
+CREATE SCHEMA visibility_schema;
+NOTICE:  DDL test: type simple, tag CREATE SCHEMA
+CREATE TABLE visibility_schema.test2 (id int);
+NOTICE:  DDL test: type simple, tag CREATE TABLE
+CREATE INDEX idx_vis2 ON visibility_schema.test2(id);
+NOTICE:  DDL test: type simple, tag CREATE INDEX
+ALTER INDEX visibility_schema.idx_vis2 INVISIBLE;
+NOTICE:  DDL test: type alter table, tag ALTER INDEX
+NOTICE:    subcommand: type SET INVISIBLE desc <NULL>
+-- Clean up
+DROP SCHEMA visibility_schema CASCADE;
+NOTICE:  drop cascades to table visibility_schema.test2
+DROP TABLE visibility_test CASCADE;
diff --git a/src/test/modules/test_ddl_deparse/meson.build b/src/test/modules/test_ddl_deparse/meson.build
index bff65ba633..6654b5e46d 100644
--- a/src/test/modules/test_ddl_deparse/meson.build
+++ b/src/test/modules/test_ddl_deparse/meson.build
@@ -48,6 +48,7 @@ tests += {
       'opfamily',
       'defprivs',
       'matviews',
+      'alter_index',
     ],
   },
 }
diff --git a/src/test/modules/test_ddl_deparse/sql/alter_index.sql b/src/test/modules/test_ddl_deparse/sql/alter_index.sql
new file mode 100644
index 0000000000..7a34dc6692
--- /dev/null
+++ b/src/test/modules/test_ddl_deparse/sql/alter_index.sql
@@ -0,0 +1,18 @@
+-- Test index visibility commands
+CREATE TABLE visibility_test (id int);
+CREATE INDEX idx_vis ON visibility_test(id);
+
+ALTER INDEX idx_vis INVISIBLE;
+ALTER INDEX idx_vis VISIBLE;
+
+ALTER INDEX idx_vis INVISIBLE;
+REINDEX INDEX idx_vis;
+
+CREATE SCHEMA visibility_schema;
+CREATE TABLE visibility_schema.test2 (id int);
+CREATE INDEX idx_vis2 ON visibility_schema.test2(id);
+ALTER INDEX visibility_schema.idx_vis2 INVISIBLE;
+
+-- Clean up
+DROP SCHEMA visibility_schema CASCADE;
+DROP TABLE visibility_test CASCADE;
diff --git a/src/test/modules/test_ddl_deparse/test_ddl_deparse.c b/src/test/modules/test_ddl_deparse/test_ddl_deparse.c
index 193669f2bc..8d7c7e5894 100644
--- a/src/test/modules/test_ddl_deparse/test_ddl_deparse.c
+++ b/src/test/modules/test_ddl_deparse/test_ddl_deparse.c
@@ -308,6 +308,12 @@ get_altertable_subcmdinfo(PG_FUNCTION_ARGS)
 			case AT_ReAddStatistics:
 				strtype = "(re) ADD STATS";
 				break;
+			case AT_SetIndexVisible:
+				strtype = "SET VISIBLE";
+				break;
+			case AT_SetIndexInvisible:
+				strtype = "SET INVISIBLE";
+				break;
 		}
 
 		if (subcmd->recurse)
diff --git a/src/test/regress/expected/create_index.out b/src/test/regress/expected/create_index.out
index bd5f002cf2..3c61a87af2 100644
--- a/src/test/regress/expected/create_index.out
+++ b/src/test/regress/expected/create_index.out
@@ -3363,6 +3363,801 @@ ERROR:  REINDEX SCHEMA cannot run inside a transaction block
 END;
 -- concurrently
 REINDEX SCHEMA CONCURRENTLY schema_to_reindex;
+-- Test index visibility functionality
+CREATE TABLE index_test(
+    id INT PRIMARY KEY,
+    data TEXT,
+    num INT,
+    vector INT[],
+    range INT4RANGE
+);
+INSERT INTO index_test
+SELECT
+    g,
+    'data ' || g,
+    g % 100,
+    ARRAY[g, g+1, g+2],
+    int4range(g, g+10)
+FROM generate_series(1, 1000) g;
+-- Function for testing
+CREATE FUNCTION get_data_length(text) RETURNS INT AS $$
+    SELECT length($1);
+$$ LANGUAGE SQL IMMUTABLE;
+-- Helper function to show index status
+CREATE OR REPLACE FUNCTION show_index_status(index_name text)
+RETURNS TABLE (
+    indexrelid regclass,
+    indisvalid boolean,
+    indisready boolean,
+    indislive boolean,
+    indisvisible boolean
+) AS $$
+BEGIN
+    RETURN QUERY EXECUTE format('
+        SELECT indexrelid::regclass, indisvalid, indisready, indislive, indisvisible
+        FROM pg_index
+        WHERE indexrelid = %L::regclass', index_name);
+END;
+$$ LANGUAGE plpgsql;
+-- Create and test each index type
+-- 1. Basic single-column index
+CREATE INDEX idx_single ON index_test(data);
+SELECT show_index_status('idx_single');
+  show_index_status   
+----------------------
+ (idx_single,t,t,t,t)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE data = 'data 500';
+                  QUERY PLAN                   
+-----------------------------------------------
+ Bitmap Heap Scan on index_test
+   Recheck Cond: (data = 'data 500'::text)
+   ->  Bitmap Index Scan on idx_single
+         Index Cond: (data = 'data 500'::text)
+(4 rows)
+
+ALTER INDEX idx_single INVISIBLE;
+SELECT show_index_status('idx_single');
+  show_index_status   
+----------------------
+ (idx_single,t,t,t,f)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE data = 'data 500';
+             QUERY PLAN              
+-------------------------------------
+ Seq Scan on index_test
+   Filter: (data = 'data 500'::text)
+(2 rows)
+
+ALTER INDEX idx_single VISIBLE;
+SELECT show_index_status('idx_single');
+  show_index_status   
+----------------------
+ (idx_single,t,t,t,t)
+(1 row)
+
+-- 2. Multi-column index
+CREATE INDEX idx_multi ON index_test(num, data);
+SELECT show_index_status('idx_multi');
+  show_index_status  
+---------------------
+ (idx_multi,t,t,t,t)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE num = 50 AND data > 'data 500';
+                           QUERY PLAN                           
+----------------------------------------------------------------
+ Bitmap Heap Scan on index_test
+   Recheck Cond: ((num = 50) AND (data > 'data 500'::text))
+   ->  Bitmap Index Scan on idx_multi
+         Index Cond: ((num = 50) AND (data > 'data 500'::text))
+(4 rows)
+
+ALTER INDEX idx_multi INVISIBLE;
+SELECT show_index_status('idx_multi');
+  show_index_status  
+---------------------
+ (idx_multi,t,t,t,f)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE num = 50 AND data > 'data 500';
+                      QUERY PLAN                      
+------------------------------------------------------
+ Seq Scan on index_test
+   Filter: ((data > 'data 500'::text) AND (num = 50))
+(2 rows)
+
+ALTER INDEX idx_multi VISIBLE;
+SELECT show_index_status('idx_multi');
+  show_index_status  
+---------------------
+ (idx_multi,t,t,t,t)
+(1 row)
+
+-- 3. Partial index
+CREATE INDEX idx_partial ON index_test(num) WHERE num < 50;
+SELECT show_index_status('idx_partial');
+   show_index_status   
+-----------------------
+ (idx_partial,t,t,t,t)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE num = 25;
+               QUERY PLAN               
+----------------------------------------
+ Bitmap Heap Scan on index_test
+   Recheck Cond: (num = 25)
+   ->  Bitmap Index Scan on idx_partial
+         Index Cond: (num = 25)
+(4 rows)
+
+ALTER INDEX idx_partial INVISIBLE;
+SELECT show_index_status('idx_partial');
+   show_index_status   
+-----------------------
+ (idx_partial,t,t,t,f)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE num = 25;
+              QUERY PLAN              
+--------------------------------------
+ Bitmap Heap Scan on index_test
+   Recheck Cond: (num = 25)
+   ->  Bitmap Index Scan on idx_multi
+         Index Cond: (num = 25)
+(4 rows)
+
+ALTER INDEX idx_partial VISIBLE;
+SELECT show_index_status('idx_partial');
+   show_index_status   
+-----------------------
+ (idx_partial,t,t,t,t)
+(1 row)
+
+-- 4. Expression index
+CREATE INDEX idx_expression ON index_test((lower(data)));
+SELECT show_index_status('idx_expression');
+    show_index_status     
+--------------------------
+ (idx_expression,t,t,t,t)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE lower(data) = 'data 500';
+                      QUERY PLAN                      
+------------------------------------------------------
+ Bitmap Heap Scan on index_test
+   Recheck Cond: (lower(data) = 'data 500'::text)
+   ->  Bitmap Index Scan on idx_expression
+         Index Cond: (lower(data) = 'data 500'::text)
+(4 rows)
+
+ALTER INDEX idx_expression INVISIBLE;
+SELECT show_index_status('idx_expression');
+    show_index_status     
+--------------------------
+ (idx_expression,t,t,t,f)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE lower(data) = 'data 500';
+                 QUERY PLAN                 
+--------------------------------------------
+ Seq Scan on index_test
+   Filter: (lower(data) = 'data 500'::text)
+(2 rows)
+
+ALTER INDEX idx_expression VISIBLE;
+SELECT show_index_status('idx_expression');
+    show_index_status     
+--------------------------
+ (idx_expression,t,t,t,t)
+(1 row)
+
+-- 5. GIN index
+CREATE INDEX idx_gin ON index_test USING gin(vector);
+SELECT show_index_status('idx_gin');
+ show_index_status 
+-------------------
+ (idx_gin,t,t,t,t)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE vector @> ARRAY[500];
+                     QUERY PLAN                     
+----------------------------------------------------
+ Bitmap Heap Scan on index_test
+   Recheck Cond: (vector @> '{500}'::integer[])
+   ->  Bitmap Index Scan on idx_gin
+         Index Cond: (vector @> '{500}'::integer[])
+(4 rows)
+
+ALTER INDEX idx_gin INVISIBLE;
+SELECT show_index_status('idx_gin');
+ show_index_status 
+-------------------
+ (idx_gin,t,t,t,f)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE vector @> ARRAY[500];
+                QUERY PLAN                
+------------------------------------------
+ Seq Scan on index_test
+   Filter: (vector @> '{500}'::integer[])
+(2 rows)
+
+ALTER INDEX idx_gin VISIBLE;
+SELECT show_index_status('idx_gin');
+ show_index_status 
+-------------------
+ (idx_gin,t,t,t,t)
+(1 row)
+
+-- 6. GiST index
+CREATE INDEX idx_gist ON index_test USING gist(range);
+SELECT show_index_status('idx_gist');
+ show_index_status  
+--------------------
+ (idx_gist,t,t,t,t)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE range && int4range(100, 110);
+                      QUERY PLAN                       
+-------------------------------------------------------
+ Bitmap Heap Scan on index_test
+   Recheck Cond: (range && '[100,110)'::int4range)
+   ->  Bitmap Index Scan on idx_gist
+         Index Cond: (range && '[100,110)'::int4range)
+(4 rows)
+
+ALTER INDEX idx_gist INVISIBLE;
+SELECT show_index_status('idx_gist');
+ show_index_status  
+--------------------
+ (idx_gist,t,t,t,f)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE range && int4range(100, 110);
+                 QUERY PLAN                  
+---------------------------------------------
+ Seq Scan on index_test
+   Filter: (range && '[100,110)'::int4range)
+(2 rows)
+
+ALTER INDEX idx_gist VISIBLE;
+SELECT show_index_status('idx_gist');
+ show_index_status  
+--------------------
+ (idx_gist,t,t,t,t)
+(1 row)
+
+-- 7. Covering index
+CREATE INDEX idx_covering ON index_test(num) INCLUDE (data);
+SELECT show_index_status('idx_covering');
+   show_index_status    
+------------------------
+ (idx_covering,t,t,t,t)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT num, data FROM index_test WHERE num = 50;
+               QUERY PLAN                
+-----------------------------------------
+ Bitmap Heap Scan on index_test
+   Recheck Cond: (num = 50)
+   ->  Bitmap Index Scan on idx_covering
+         Index Cond: (num = 50)
+(4 rows)
+
+ALTER INDEX idx_covering INVISIBLE;
+SELECT show_index_status('idx_covering');
+   show_index_status    
+------------------------
+ (idx_covering,t,t,t,f)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT num, data FROM index_test WHERE num = 50;
+              QUERY PLAN              
+--------------------------------------
+ Bitmap Heap Scan on index_test
+   Recheck Cond: (num = 50)
+   ->  Bitmap Index Scan on idx_multi
+         Index Cond: (num = 50)
+(4 rows)
+
+ALTER INDEX idx_covering VISIBLE;
+SELECT show_index_status('idx_covering');
+   show_index_status    
+------------------------
+ (idx_covering,t,t,t,t)
+(1 row)
+
+-- 8. Unique index
+CREATE UNIQUE INDEX idx_unique ON index_test(id, data);
+SELECT show_index_status('idx_unique');
+  show_index_status   
+----------------------
+ (idx_unique,t,t,t,t)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE id = 500 AND data = 'data 500';
+                        QUERY PLAN                        
+----------------------------------------------------------
+ Index Scan using idx_unique on index_test
+   Index Cond: ((id = 500) AND (data = 'data 500'::text))
+(2 rows)
+
+ALTER INDEX idx_unique INVISIBLE;
+SELECT show_index_status('idx_unique');
+  show_index_status   
+----------------------
+ (idx_unique,t,t,t,f)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE id = 500 AND data = 'data 500';
+                   QUERY PLAN                   
+------------------------------------------------
+ Index Scan using index_test_pkey on index_test
+   Index Cond: (id = 500)
+   Filter: (data = 'data 500'::text)
+(3 rows)
+
+ALTER INDEX idx_unique VISIBLE;
+SELECT show_index_status('idx_unique');
+  show_index_status   
+----------------------
+ (idx_unique,t,t,t,t)
+(1 row)
+
+-- 9. Function-based index
+CREATE INDEX idx_func ON index_test(get_data_length(data));
+SELECT show_index_status('idx_func');
+ show_index_status  
+--------------------
+ (idx_func,t,t,t,t)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE get_data_length(data) = 10;
+               QUERY PLAN                
+-----------------------------------------
+ Bitmap Heap Scan on index_test
+   Recheck Cond: (length(data) = 10)
+   ->  Bitmap Index Scan on idx_func
+         Index Cond: (length(data) = 10)
+(4 rows)
+
+ALTER INDEX idx_func INVISIBLE;
+SELECT show_index_status('idx_func');
+ show_index_status  
+--------------------
+ (idx_func,t,t,t,f)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE get_data_length(data) = 10;
+          QUERY PLAN           
+-------------------------------
+ Seq Scan on index_test
+   Filter: (length(data) = 10)
+(2 rows)
+
+ALTER INDEX idx_func VISIBLE;
+SELECT show_index_status('idx_func');
+ show_index_status  
+--------------------
+ (idx_func,t,t,t,t)
+(1 row)
+
+-- 10. Join index
+CREATE TABLE join_test (id INT PRIMARY KEY, ref_id INT);
+INSERT INTO join_test SELECT g, g % 100 FROM generate_series(1, 1000) g;
+CREATE INDEX idx_join ON join_test(ref_id);
+SELECT show_index_status('idx_join');
+ show_index_status  
+--------------------
+ (idx_join,t,t,t,t)
+(1 row)
+
+EXPLAIN (COSTS OFF)
+SELECT jt.id, it.data
+FROM join_test jt
+JOIN index_test it ON jt.ref_id = it.num
+WHERE jt.id BETWEEN 100 AND 200;
+                          QUERY PLAN                           
+---------------------------------------------------------------
+ Hash Join
+   Hash Cond: (it.num = jt.ref_id)
+   ->  Seq Scan on index_test it
+   ->  Hash
+         ->  Bitmap Heap Scan on join_test jt
+               Recheck Cond: ((id >= 100) AND (id <= 200))
+               ->  Bitmap Index Scan on join_test_pkey
+                     Index Cond: ((id >= 100) AND (id <= 200))
+(8 rows)
+
+-- Set all indexes to invisible to force seq scan
+ALTER INDEX idx_join INVISIBLE;
+ALTER INDEX join_test_pkey INVISIBLE;
+SELECT show_index_status('idx_join');
+ show_index_status  
+--------------------
+ (idx_join,t,t,t,f)
+(1 row)
+
+SELECT show_index_status('join_test_pkey');
+    show_index_status     
+--------------------------
+ (join_test_pkey,t,t,t,f)
+(1 row)
+
+EXPLAIN (COSTS OFF)
+SELECT jt.id, it.data
+FROM join_test jt
+JOIN index_test it ON jt.ref_id = it.num
+WHERE jt.id BETWEEN 100 AND 200;
+                     QUERY PLAN                      
+-----------------------------------------------------
+ Hash Join
+   Hash Cond: (it.num = jt.ref_id)
+   ->  Seq Scan on index_test it
+   ->  Hash
+         ->  Seq Scan on join_test jt
+               Filter: ((id >= 100) AND (id <= 200))
+(6 rows)
+
+ALTER INDEX idx_join VISIBLE;
+ALTER INDEX join_test_pkey VISIBLE;
+SELECT show_index_status('idx_join');
+ show_index_status  
+--------------------
+ (idx_join,t,t,t,t)
+(1 row)
+
+SELECT show_index_status('join_test_pkey');
+    show_index_status     
+--------------------------
+ (join_test_pkey,t,t,t,t)
+(1 row)
+
+-- Test REINDEX CONCURRENTLY
+REINDEX INDEX CONCURRENTLY idx_join;
+SELECT show_index_status('idx_join');
+ show_index_status  
+--------------------
+ (idx_join,t,t,t,t)
+(1 row)
+
+ALTER INDEX idx_join INVISIBLE;
+SELECT show_index_status('idx_join');
+ show_index_status  
+--------------------
+ (idx_join,t,t,t,f)
+(1 row)
+
+REINDEX INDEX CONCURRENTLY idx_join;
+SELECT show_index_status('idx_join');
+ show_index_status  
+--------------------
+ (idx_join,t,t,t,f)
+(1 row)
+
+SELECT pg_get_indexdef('idx_join'::regclass);
+                                   pg_get_indexdef                                   
+-------------------------------------------------------------------------------------
+ CREATE INDEX idx_join ON schema_to_reindex.join_test USING btree (ref_id) INVISIBLE
+(1 row)
+
+ALTER INDEX idx_join VISIBLE;
+SELECT pg_get_indexdef('idx_join'::regclass);
+                              pg_get_indexdef                              
+---------------------------------------------------------------------------
+ CREATE INDEX idx_join ON schema_to_reindex.join_test USING btree (ref_id)
+(1 row)
+
+-- Test index visibility with indcheckxmin being true
+CREATE TABLE indcheckxmin_test(id int PRIMARY KEY);
+INSERT INTO indcheckxmin_test VALUES (1), (2), (3);
+CREATE INDEX CONCURRENTLY idx_checkxmin ON indcheckxmin_test(id);
+BEGIN;
+-- Simulate indcheckxmin being true
+UPDATE pg_index SET indcheckxmin = true WHERE indexrelid = 'idx_checkxmin'::regclass;
+ALTER INDEX idx_checkxmin INVISIBLE;  -- expect fail
+ERROR:  cannot update index visibility while indcheckxmin is true
+HINT:  Wait for all transactions that might see inconsistent HOT chains to complete
+ROLLBACK;
+-- Test prepared statements with index visibility
+CREATE TABLE prep_idx_test (id int, data text);
+CREATE INDEX prep_idx1 ON prep_idx_test(data);
+INSERT INTO prep_idx_test SELECT g, 'data ' || g FROM generate_series(1,100) g;
+-- Test with visible index
+PREPARE idx_plan AS SELECT * FROM prep_idx_test WHERE data = $1;
+EXPLAIN (COSTS OFF) EXECUTE idx_plan('data 1');
+                 QUERY PLAN                  
+---------------------------------------------
+ Bitmap Heap Scan on prep_idx_test
+   Recheck Cond: (data = 'data 1'::text)
+   ->  Bitmap Index Scan on prep_idx1
+         Index Cond: (data = 'data 1'::text)
+(4 rows)
+
+EXECUTE idx_plan('data 1');
+ id |  data  
+----+--------
+  1 | data 1
+(1 row)
+
+-- Test with invisible index
+ALTER INDEX prep_idx1 INVISIBLE;
+EXPLAIN (COSTS OFF) EXECUTE idx_plan('data 1');
+            QUERY PLAN             
+-----------------------------------
+ Seq Scan on prep_idx_test
+   Filter: (data = 'data 1'::text)
+(2 rows)
+
+EXECUTE idx_plan('data 1');
+ id |  data  
+----+--------
+  1 | data 1
+(1 row)
+
+-- Test with use_invisible_index
+SET use_invisible_index TO on;
+EXPLAIN (COSTS OFF) EXECUTE idx_plan('data 1');
+                 QUERY PLAN                  
+---------------------------------------------
+ Bitmap Heap Scan on prep_idx_test
+   Recheck Cond: (data = 'data 1'::text)
+   ->  Bitmap Index Scan on prep_idx1
+         Index Cond: (data = 'data 1'::text)
+(4 rows)
+
+EXECUTE idx_plan('data 1');
+ id |  data  
+----+--------
+  1 | data 1
+(1 row)
+
+SET use_invisible_index TO off;
+-- Assert plan cache is reset and index is not used
+EXPLAIN (COSTS OFF) EXECUTE idx_plan('data 1');
+            QUERY PLAN             
+-----------------------------------
+ Seq Scan on prep_idx_test
+   Filter: (data = 'data 1'::text)
+(2 rows)
+
+-- Make index visible and test again
+ALTER INDEX prep_idx1 VISIBLE;
+EXPLAIN (COSTS OFF) EXECUTE idx_plan('data 1');
+                 QUERY PLAN                  
+---------------------------------------------
+ Bitmap Heap Scan on prep_idx_test
+   Recheck Cond: (data = 'data 1'::text)
+   ->  Bitmap Index Scan on prep_idx1
+         Index Cond: (data = 'data 1'::text)
+(4 rows)
+
+EXECUTE idx_plan('data 1');
+ id |  data  
+----+--------
+  1 | data 1
+(1 row)
+
+-- Test index visibility with partitioned tables
+CREATE TABLE part_tbl(id int, data text) PARTITION BY RANGE(id);
+CREATE TABLE part1 PARTITION OF part_tbl FOR VALUES FROM (1) TO (100);
+CREATE TABLE part2 PARTITION OF part_tbl FOR VALUES FROM (100) TO (200);
+INSERT INTO part_tbl
+SELECT g, 'data ' || g
+FROM generate_series(1, 199) g;
+CREATE INDEX idx_part_tbl ON part_tbl(data);
+SELECT c.relname, i.indisvisible
+FROM pg_index i
+JOIN pg_class c ON i.indexrelid = c.oid
+WHERE c.relname LIKE 'idx_part_tbl%'
+ORDER BY c.relname;
+   relname    | indisvisible 
+--------------+--------------
+ idx_part_tbl | t
+(1 row)
+
+-- Force use of indexes to avoid flaky test results
+SET enable_seqscan = off;
+EXPLAIN (COSTS OFF)
+SELECT * FROM part_tbl WHERE data = 'data 50';
+                        QUERY PLAN                         
+-----------------------------------------------------------
+ Append
+   ->  Index Scan using part1_data_idx on part1 part_tbl_1
+         Index Cond: (data = 'data 50'::text)
+   ->  Index Scan using part2_data_idx on part2 part_tbl_2
+         Index Cond: (data = 'data 50'::text)
+(5 rows)
+
+ALTER INDEX idx_part_tbl INVISIBLE;
+SELECT c.relname, i.indisvisible
+FROM pg_index i
+JOIN pg_class c ON i.indexrelid = c.oid
+WHERE c.relname LIKE 'idx_part_tbl%'
+ORDER BY c.relname;
+   relname    | indisvisible 
+--------------+--------------
+ idx_part_tbl | f
+(1 row)
+
+-- Check query plan after setting invisible (should use seq scan)
+EXPLAIN (COSTS OFF)
+SELECT * FROM part_tbl WHERE data = 'data 50';
+                QUERY PLAN                
+------------------------------------------
+ Append
+   ->  Seq Scan on part1 part_tbl_1
+         Disabled: true
+         Filter: (data = 'data 50'::text)
+   ->  Seq Scan on part2 part_tbl_2
+         Disabled: true
+         Filter: (data = 'data 50'::text)
+(7 rows)
+
+SET use_invisible_index TO on;
+EXPLAIN (COSTS OFF)
+SELECT * FROM part_tbl WHERE data = 'data 50';
+                        QUERY PLAN                         
+-----------------------------------------------------------
+ Append
+   ->  Index Scan using part1_data_idx on part1 part_tbl_1
+         Index Cond: (data = 'data 50'::text)
+   ->  Index Scan using part2_data_idx on part2 part_tbl_2
+         Index Cond: (data = 'data 50'::text)
+(5 rows)
+
+SET use_invisible_index TO off;
+EXPLAIN (COSTS OFF)
+SELECT * FROM part_tbl WHERE data = 'data 50';
+                QUERY PLAN                
+------------------------------------------
+ Append
+   ->  Seq Scan on part1 part_tbl_1
+         Disabled: true
+         Filter: (data = 'data 50'::text)
+   ->  Seq Scan on part2 part_tbl_2
+         Disabled: true
+         Filter: (data = 'data 50'::text)
+(7 rows)
+
+ALTER INDEX idx_part_tbl VISIBLE;
+SELECT c.relname, i.indisvisible
+FROM pg_index i
+JOIN pg_class c ON i.indexrelid = c.oid
+WHERE c.relname LIKE 'idx_part_tbl%'
+ORDER BY c.relname;
+   relname    | indisvisible 
+--------------+--------------
+ idx_part_tbl | t
+(1 row)
+
+EXPLAIN (COSTS OFF)
+SELECT * FROM part_tbl WHERE data = 'data 50';
+                        QUERY PLAN                         
+-----------------------------------------------------------
+ Append
+   ->  Index Scan using part1_data_idx on part1 part_tbl_1
+         Index Cond: (data = 'data 50'::text)
+   ->  Index Scan using part2_data_idx on part2 part_tbl_2
+         Index Cond: (data = 'data 50'::text)
+(5 rows)
+
+SET enable_seqscan = on;
+-- Test REINDEX maintains visibility setting
+ALTER INDEX idx_part_tbl INVISIBLE;
+REINDEX INDEX idx_part_tbl;
+SELECT c.relname, i.indisvisible
+FROM pg_index i
+JOIN pg_class c ON i.indexrelid = c.oid
+WHERE c.relname LIKE 'idx_part_tbl%'
+ORDER BY c.relname;
+   relname    | indisvisible 
+--------------+--------------
+ idx_part_tbl | f
+(1 row)
+
+-- Test that index visibility is preserved after ALTER TABLE
+CREATE TABLE vis_test(id INT PRIMARY KEY, data text);
+\d vis_test
+        Table "schema_to_reindex.vis_test"
+ Column |  Type   | Collation | Nullable | Default 
+--------+---------+-----------+----------+---------
+ id     | integer |           | not null | 
+ data   | text    |           |          | 
+Indexes:
+    "vis_test_pkey" PRIMARY KEY, btree (id)
+
+ALTER INDEX vis_test_pkey INVISIBLE;
+\d vis_test
+        Table "schema_to_reindex.vis_test"
+ Column |  Type   | Collation | Nullable | Default 
+--------+---------+-----------+----------+---------
+ id     | integer |           | not null | 
+ data   | text    |           |          | 
+Indexes:
+    "vis_test_pkey" PRIMARY KEY, btree (id) INVISIBLE
+
+ALTER TABLE vis_test ALTER COLUMN id SET DATA TYPE bigint;
+\d vis_test
+        Table "schema_to_reindex.vis_test"
+ Column |  Type  | Collation | Nullable | Default 
+--------+--------+-----------+----------+---------
+ id     | bigint |           | not null | 
+ data   | text   |           |          | 
+Indexes:
+    "vis_test_pkey" PRIMARY KEY, btree (id) INVISIBLE
+
+ALTER TABLE vis_test ALTER COLUMN id SET DATA TYPE int;
+\d vis_test
+        Table "schema_to_reindex.vis_test"
+ Column |  Type   | Collation | Nullable | Default 
+--------+---------+-----------+----------+---------
+ id     | integer |           | not null | 
+ data   | text    |           |          | 
+Indexes:
+    "vis_test_pkey" PRIMARY KEY, btree (id) INVISIBLE
+
+ALTER INDEX vis_test_pkey VISIBLE;
+\d vis_test
+        Table "schema_to_reindex.vis_test"
+ Column |  Type   | Collation | Nullable | Default 
+--------+---------+-----------+----------+---------
+ id     | integer |           | not null | 
+ data   | text    |           |          | 
+Indexes:
+    "vis_test_pkey" PRIMARY KEY, btree (id)
+
+-- Test CREATE INDEX with INVISIBLE option
+CREATE TABLE invis_test(id int, data text);
+INSERT INTO invis_test SELECT g, 'data ' || g FROM generate_series(1,100) g;
+CREATE INDEX idx_invis1 ON invis_test(data) INVISIBLE;
+\d invis_test
+       Table "schema_to_reindex.invis_test"
+ Column |  Type   | Collation | Nullable | Default 
+--------+---------+-----------+----------+---------
+ id     | integer |           |          | 
+ data   | text    |           |          | 
+Indexes:
+    "idx_invis1" btree (data) INVISIBLE
+
+\d idx_invis1
+Index "schema_to_reindex.idx_invis1"
+ Column | Type | Key? | Definition 
+--------+------+------+------------
+ data   | text | yes  | data
+btree, for table "schema_to_reindex.invis_test", invisible
+
+ALTER INDEX idx_invis1 VISIBLE;
+\d invis_test
+       Table "schema_to_reindex.invis_test"
+ Column |  Type   | Collation | Nullable | Default 
+--------+---------+-----------+----------+---------
+ id     | integer |           |          | 
+ data   | text    |           |          | 
+Indexes:
+    "idx_invis1" btree (data)
+
+\d idx_invis1
+Index "schema_to_reindex.idx_invis1"
+ Column | Type | Key? | Definition 
+--------+------+------+------------
+ data   | text | yes  | data
+btree, for table "schema_to_reindex.invis_test"
+
+-- Clean up
+DROP TABLE index_test;
+DROP TABLE join_test;
+DROP FUNCTION get_data_length;
+DROP FUNCTION show_index_status;
+DROP TABLE indcheckxmin_test CASCADE;
+DEALLOCATE idx_plan;
+DROP TABLE prep_idx_test;
+DROP TABLE part_tbl CASCADE;
+DROP TABLE vis_test;
+DROP TABLE invis_test;
 -- Failure for unauthorized user
 CREATE ROLE regress_reindexuser NOLOGIN;
 SET SESSION ROLE regress_reindexuser;
diff --git a/src/test/regress/sql/create_index.sql b/src/test/regress/sql/create_index.sql
index be570da08a..84f577df7d 100644
--- a/src/test/regress/sql/create_index.sql
+++ b/src/test/regress/sql/create_index.sql
@@ -1424,6 +1424,327 @@ END;
 -- concurrently
 REINDEX SCHEMA CONCURRENTLY schema_to_reindex;
 
+-- Test index visibility functionality
+
+CREATE TABLE index_test(
+    id INT PRIMARY KEY,
+    data TEXT,
+    num INT,
+    vector INT[],
+    range INT4RANGE
+);
+
+INSERT INTO index_test
+SELECT
+    g,
+    'data ' || g,
+    g % 100,
+    ARRAY[g, g+1, g+2],
+    int4range(g, g+10)
+FROM generate_series(1, 1000) g;
+
+-- Function for testing
+CREATE FUNCTION get_data_length(text) RETURNS INT AS $$
+    SELECT length($1);
+$$ LANGUAGE SQL IMMUTABLE;
+
+-- Helper function to show index status
+CREATE OR REPLACE FUNCTION show_index_status(index_name text)
+RETURNS TABLE (
+    indexrelid regclass,
+    indisvalid boolean,
+    indisready boolean,
+    indislive boolean,
+    indisvisible boolean
+) AS $$
+BEGIN
+    RETURN QUERY EXECUTE format('
+        SELECT indexrelid::regclass, indisvalid, indisready, indislive, indisvisible
+        FROM pg_index
+        WHERE indexrelid = %L::regclass', index_name);
+END;
+$$ LANGUAGE plpgsql;
+
+-- Create and test each index type
+-- 1. Basic single-column index
+CREATE INDEX idx_single ON index_test(data);
+SELECT show_index_status('idx_single');
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE data = 'data 500';
+ALTER INDEX idx_single INVISIBLE;
+SELECT show_index_status('idx_single');
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE data = 'data 500';
+ALTER INDEX idx_single VISIBLE;
+SELECT show_index_status('idx_single');
+
+-- 2. Multi-column index
+CREATE INDEX idx_multi ON index_test(num, data);
+SELECT show_index_status('idx_multi');
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE num = 50 AND data > 'data 500';
+ALTER INDEX idx_multi INVISIBLE;
+SELECT show_index_status('idx_multi');
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE num = 50 AND data > 'data 500';
+ALTER INDEX idx_multi VISIBLE;
+SELECT show_index_status('idx_multi');
+
+-- 3. Partial index
+CREATE INDEX idx_partial ON index_test(num) WHERE num < 50;
+SELECT show_index_status('idx_partial');
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE num = 25;
+ALTER INDEX idx_partial INVISIBLE;
+SELECT show_index_status('idx_partial');
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE num = 25;
+ALTER INDEX idx_partial VISIBLE;
+SELECT show_index_status('idx_partial');
+
+-- 4. Expression index
+CREATE INDEX idx_expression ON index_test((lower(data)));
+SELECT show_index_status('idx_expression');
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE lower(data) = 'data 500';
+ALTER INDEX idx_expression INVISIBLE;
+SELECT show_index_status('idx_expression');
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE lower(data) = 'data 500';
+ALTER INDEX idx_expression VISIBLE;
+SELECT show_index_status('idx_expression');
+
+-- 5. GIN index
+CREATE INDEX idx_gin ON index_test USING gin(vector);
+SELECT show_index_status('idx_gin');
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE vector @> ARRAY[500];
+ALTER INDEX idx_gin INVISIBLE;
+SELECT show_index_status('idx_gin');
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE vector @> ARRAY[500];
+ALTER INDEX idx_gin VISIBLE;
+SELECT show_index_status('idx_gin');
+
+-- 6. GiST index
+CREATE INDEX idx_gist ON index_test USING gist(range);
+SELECT show_index_status('idx_gist');
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE range && int4range(100, 110);
+ALTER INDEX idx_gist INVISIBLE;
+SELECT show_index_status('idx_gist');
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE range && int4range(100, 110);
+ALTER INDEX idx_gist VISIBLE;
+SELECT show_index_status('idx_gist');
+
+-- 7. Covering index
+CREATE INDEX idx_covering ON index_test(num) INCLUDE (data);
+SELECT show_index_status('idx_covering');
+EXPLAIN (COSTS OFF) SELECT num, data FROM index_test WHERE num = 50;
+ALTER INDEX idx_covering INVISIBLE;
+SELECT show_index_status('idx_covering');
+EXPLAIN (COSTS OFF) SELECT num, data FROM index_test WHERE num = 50;
+ALTER INDEX idx_covering VISIBLE;
+SELECT show_index_status('idx_covering');
+
+-- 8. Unique index
+CREATE UNIQUE INDEX idx_unique ON index_test(id, data);
+SELECT show_index_status('idx_unique');
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE id = 500 AND data = 'data 500';
+ALTER INDEX idx_unique INVISIBLE;
+SELECT show_index_status('idx_unique');
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE id = 500 AND data = 'data 500';
+ALTER INDEX idx_unique VISIBLE;
+SELECT show_index_status('idx_unique');
+
+-- 9. Function-based index
+CREATE INDEX idx_func ON index_test(get_data_length(data));
+SELECT show_index_status('idx_func');
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE get_data_length(data) = 10;
+ALTER INDEX idx_func INVISIBLE;
+SELECT show_index_status('idx_func');
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE get_data_length(data) = 10;
+ALTER INDEX idx_func VISIBLE;
+SELECT show_index_status('idx_func');
+
+-- 10. Join index
+CREATE TABLE join_test (id INT PRIMARY KEY, ref_id INT);
+INSERT INTO join_test SELECT g, g % 100 FROM generate_series(1, 1000) g;
+CREATE INDEX idx_join ON join_test(ref_id);
+SELECT show_index_status('idx_join');
+
+EXPLAIN (COSTS OFF)
+SELECT jt.id, it.data
+FROM join_test jt
+JOIN index_test it ON jt.ref_id = it.num
+WHERE jt.id BETWEEN 100 AND 200;
+
+-- Set all indexes to invisible to force seq scan
+ALTER INDEX idx_join INVISIBLE;
+ALTER INDEX join_test_pkey INVISIBLE;
+SELECT show_index_status('idx_join');
+SELECT show_index_status('join_test_pkey');
+
+EXPLAIN (COSTS OFF)
+SELECT jt.id, it.data
+FROM join_test jt
+JOIN index_test it ON jt.ref_id = it.num
+WHERE jt.id BETWEEN 100 AND 200;
+
+ALTER INDEX idx_join VISIBLE;
+ALTER INDEX join_test_pkey VISIBLE;
+SELECT show_index_status('idx_join');
+SELECT show_index_status('join_test_pkey');
+
+-- Test REINDEX CONCURRENTLY
+REINDEX INDEX CONCURRENTLY idx_join;
+SELECT show_index_status('idx_join');
+
+ALTER INDEX idx_join INVISIBLE;
+SELECT show_index_status('idx_join');
+REINDEX INDEX CONCURRENTLY idx_join;
+SELECT show_index_status('idx_join');
+
+SELECT pg_get_indexdef('idx_join'::regclass);
+ALTER INDEX idx_join VISIBLE;
+SELECT pg_get_indexdef('idx_join'::regclass);
+
+-- Test index visibility with indcheckxmin being true
+
+CREATE TABLE indcheckxmin_test(id int PRIMARY KEY);
+INSERT INTO indcheckxmin_test VALUES (1), (2), (3);
+CREATE INDEX CONCURRENTLY idx_checkxmin ON indcheckxmin_test(id);
+BEGIN;
+-- Simulate indcheckxmin being true
+UPDATE pg_index SET indcheckxmin = true WHERE indexrelid = 'idx_checkxmin'::regclass;
+ALTER INDEX idx_checkxmin INVISIBLE;  -- expect fail
+ROLLBACK;
+
+-- Test prepared statements with index visibility
+CREATE TABLE prep_idx_test (id int, data text);
+CREATE INDEX prep_idx1 ON prep_idx_test(data);
+INSERT INTO prep_idx_test SELECT g, 'data ' || g FROM generate_series(1,100) g;
+
+-- Test with visible index
+PREPARE idx_plan AS SELECT * FROM prep_idx_test WHERE data = $1;
+EXPLAIN (COSTS OFF) EXECUTE idx_plan('data 1');
+EXECUTE idx_plan('data 1');
+
+-- Test with invisible index
+ALTER INDEX prep_idx1 INVISIBLE;
+EXPLAIN (COSTS OFF) EXECUTE idx_plan('data 1');
+EXECUTE idx_plan('data 1');
+
+-- Test with use_invisible_index
+SET use_invisible_index TO on;
+EXPLAIN (COSTS OFF) EXECUTE idx_plan('data 1');
+EXECUTE idx_plan('data 1');
+SET use_invisible_index TO off;
+-- Assert plan cache is reset and index is not used
+EXPLAIN (COSTS OFF) EXECUTE idx_plan('data 1');
+
+-- Make index visible and test again
+ALTER INDEX prep_idx1 VISIBLE;
+EXPLAIN (COSTS OFF) EXECUTE idx_plan('data 1');
+EXECUTE idx_plan('data 1');
+
+-- Test index visibility with partitioned tables
+CREATE TABLE part_tbl(id int, data text) PARTITION BY RANGE(id);
+CREATE TABLE part1 PARTITION OF part_tbl FOR VALUES FROM (1) TO (100);
+CREATE TABLE part2 PARTITION OF part_tbl FOR VALUES FROM (100) TO (200);
+
+INSERT INTO part_tbl
+SELECT g, 'data ' || g
+FROM generate_series(1, 199) g;
+
+CREATE INDEX idx_part_tbl ON part_tbl(data);
+
+SELECT c.relname, i.indisvisible
+FROM pg_index i
+JOIN pg_class c ON i.indexrelid = c.oid
+WHERE c.relname LIKE 'idx_part_tbl%'
+ORDER BY c.relname;
+
+-- Force use of indexes to avoid flaky test results
+SET enable_seqscan = off;
+
+EXPLAIN (COSTS OFF)
+SELECT * FROM part_tbl WHERE data = 'data 50';
+
+ALTER INDEX idx_part_tbl INVISIBLE;
+
+SELECT c.relname, i.indisvisible
+FROM pg_index i
+JOIN pg_class c ON i.indexrelid = c.oid
+WHERE c.relname LIKE 'idx_part_tbl%'
+ORDER BY c.relname;
+
+-- Check query plan after setting invisible (should use seq scan)
+EXPLAIN (COSTS OFF)
+SELECT * FROM part_tbl WHERE data = 'data 50';
+
+SET use_invisible_index TO on;
+
+EXPLAIN (COSTS OFF)
+SELECT * FROM part_tbl WHERE data = 'data 50';
+
+SET use_invisible_index TO off;
+
+EXPLAIN (COSTS OFF)
+SELECT * FROM part_tbl WHERE data = 'data 50';
+
+ALTER INDEX idx_part_tbl VISIBLE;
+
+SELECT c.relname, i.indisvisible
+FROM pg_index i
+JOIN pg_class c ON i.indexrelid = c.oid
+WHERE c.relname LIKE 'idx_part_tbl%'
+ORDER BY c.relname;
+
+EXPLAIN (COSTS OFF)
+SELECT * FROM part_tbl WHERE data = 'data 50';
+
+SET enable_seqscan = on;
+
+-- Test REINDEX maintains visibility setting
+ALTER INDEX idx_part_tbl INVISIBLE;
+REINDEX INDEX idx_part_tbl;
+
+SELECT c.relname, i.indisvisible
+FROM pg_index i
+JOIN pg_class c ON i.indexrelid = c.oid
+WHERE c.relname LIKE 'idx_part_tbl%'
+ORDER BY c.relname;
+
+-- Test that index visibility is preserved after ALTER TABLE
+CREATE TABLE vis_test(id INT PRIMARY KEY, data text);
+\d vis_test
+
+ALTER INDEX vis_test_pkey INVISIBLE;
+\d vis_test
+
+ALTER TABLE vis_test ALTER COLUMN id SET DATA TYPE bigint;
+\d vis_test
+
+ALTER TABLE vis_test ALTER COLUMN id SET DATA TYPE int;
+\d vis_test
+
+ALTER INDEX vis_test_pkey VISIBLE;
+\d vis_test
+
+-- Test CREATE INDEX with INVISIBLE option
+CREATE TABLE invis_test(id int, data text);
+INSERT INTO invis_test SELECT g, 'data ' || g FROM generate_series(1,100) g;
+
+CREATE INDEX idx_invis1 ON invis_test(data) INVISIBLE;
+\d invis_test
+\d idx_invis1
+
+ALTER INDEX idx_invis1 VISIBLE;
+\d invis_test
+\d idx_invis1
+
+-- Clean up
+DROP TABLE index_test;
+DROP TABLE join_test;
+DROP FUNCTION get_data_length;
+DROP FUNCTION show_index_status;
+DROP TABLE indcheckxmin_test CASCADE;
+DEALLOCATE idx_plan;
+DROP TABLE prep_idx_test;
+DROP TABLE part_tbl CASCADE;
+DROP TABLE vis_test;
+DROP TABLE invis_test;
+
 -- Failure for unauthorized user
 CREATE ROLE regress_reindexuser NOLOGIN;
 SET SESSION ROLE regress_reindexuser;
-- 
2.39.5 (Apple Git-154)

#74Shayon Mukherjee
shayonj@gmail.com
In reply to: Shayon Mukherjee (#73)
1 attachment(s)
Re: Proposal to Enable/Disable Index using ALTER INDEX (with patch)

On Sun, Feb 23, 2025 at 3:41 PM Shayon Mukherjee <shayonj@gmail.com> wrote:

I have rebased the patch on top of master (resolving some merge
conflicts), along with the meson changes (thank you for that).

Rebased against the latest master and attaching the v13 patch.

Thank you
Shayon

Attachments:

v13-0001-Introduce-the-ability-to-enable-disable-indexes-.patchapplication/octet-stream; name=v13-0001-Introduce-the-ability-to-enable-disable-indexes-.patchDownload
From 13b17525b7071a303e7c4c55536d4945f5a4341a Mon Sep 17 00:00:00 2001
From: Shayon Mukherjee <shayonj@gmail.com>
Date: Thu, 17 Oct 2024 10:04:13 -0400
Subject: [PATCH v13] Introduce the ability to enable/disable indexes using
 ALTER INDEX

This patch introduces the ability to enable or disable indexes using ALTER INDEX
and CREATE INDEX commands.

Original motivation for the problem and proposal for a patch
can be found at [1].

This patch passes all the existing specs and the newly added regression tests. The patch
is ready for review and test. It compiles, so the can patch can be applied for testing as well.

Implementation details:

- New Grammar:
  * ALTER INDEX ... ENABLE/DISABLE
  * CREATE INDEX ... DISABLE

- Default state is enabled. Indexes are only disabled when explicitly
  instructed via CREATE INDEX ... DISABLE or ALTER INDEX ... DISABLE.

- Primary Key and Unique constraint indexes are always enabled as well. The
  ENABLE/DISABLE grammar is not supported for these types of indexes. They can
  be later disabled via ALTER INDEX ... ENABLE/DISABLE.

- ALTER INDEX ... ENABLE/DISABLE performs update on the relevant row in pg_index
  catalog

- pg_get_indexdef() support the new functionality and grammar. This change is
  reflected in \d output for tables and pg_dump. We show the DISABLE syntax accordingly.

- Updated create_index.sql regression test to cover the new grammar and verify
  that disabled indexes are not used in queries. The test CATALOG_VERSION_NO

  - Basic single-column and multi-column indexes
  - Partial indexes
  - Expression indexes
  - Join indexes
  - GIN and GiST indexes
  - Covering indexes
  - Range indexes
  - Unique indexes and constraints

- Adds a new enabled attribute to the IndexOptInfo structure.

- Modifies get_relation_info in plancat.c to skip disabled indexes entirely, thus reducing the number of places we need to check if an index is disabled or not. Inspired by the conversations start at [2].
  - I chose to modify the logic within get_relation_info as compared to, say, reducing the cost to make the planner not consider an index during planning, mostly to keep the number of changes being introduced to a minimum and also the logic itself being self-contained and easier to under perhaps (?).

- No changes are made to stop the index from getting rebuilt. This way we ensure no
  data miss or corruption when index is re-nabled.

- TOAST indexes are supported and enabled by default as well.

- REINDEX CONCURRENTLY is supported as well and existing state of pg_index.indisenabled
  is carried over accordingly.

- See the changes in create_index.sql to get an idea of the grammar and sql statements.

- See the changes in create_index.out to get an idea of the catalogue states and EXPLAIN
  output to see when an index is getting used or isn't (when disabled).

- Incorporated DavidR's feedback from [3] around documentation and also you will see that by skip disabled indexes entirely from get_relation_info in plancat.c (as mentioned above), we address the other mentioned issues as well.

- Lastly, protects against the case where indcheckxmin is true by raising ERRCODE_OBJECT_NOT_IN_PREREQUISITE_STATE.

Looking forward to any and all feedback on this patch, including but not limited to code quality, tests, fundamental logic.

[1] https://www.postgresql.org/message-id/CANqtF-oXKe0M%3D0QOih6H%2BsZRjE2BWAbkW_1%2B9nMEAMLxUJg5jA%40mail.gmail.com
[2] https://www.postgresql.org/message-id/3465209.1727202064%40sss.pgh.pa.us
[3] https://www.postgresql.org/message-id/CAApHDvpUNu%3DiVcdJ74sypvgeaCF%2Btfpyb8VRhZaF7DTd1xVr7g%40mail.gmail.com
---
 doc/src/sgml/catalogs.sgml                 |  11 +
 doc/src/sgml/ref/alter_index.sgml          |  43 ++
 doc/src/sgml/ref/create_index.sgml         |  29 ++
 src/backend/bootstrap/bootparse.y          |   2 +
 src/backend/catalog/index.c                |  31 +-
 src/backend/catalog/toasting.c             |   2 +-
 src/backend/commands/indexcmds.c           |   4 +
 src/backend/commands/tablecmds.c           |  67 ++-
 src/backend/optimizer/util/plancat.c       |  13 +
 src/backend/parser/gram.y                  |  48 +-
 src/backend/parser/parse_utilcmd.c         |   3 +
 src/backend/utils/adt/ruleutils.c          |   4 +
 src/backend/utils/cache/relcache.c         |   1 +
 src/include/catalog/index.h                |   2 +-
 src/include/catalog/pg_index.h             |   1 +
 src/include/nodes/parsenodes.h             |   3 +
 src/include/nodes/pathnodes.h              |   2 +
 src/test/regress/expected/create_index.out | 505 +++++++++++++++++++++
 src/test/regress/sql/create_index.sql      | 192 ++++++++
 19 files changed, 953 insertions(+), 10 deletions(-)

diff --git a/doc/src/sgml/catalogs.sgml b/doc/src/sgml/catalogs.sgml
index fb050635551..123fcb04892 100644
--- a/doc/src/sgml/catalogs.sgml
+++ b/doc/src/sgml/catalogs.sgml
@@ -4618,6 +4618,17 @@ SCRAM-SHA-256$<replaceable>&lt;iteration count&gt;</replaceable>:<replaceable>&l
        partial index.
       </para></entry>
      </row>
+
+     <row>
+      <entry role="catalog_table_entry"><para role="column_definition">
+       <structfield>indisenabled</structfield> <type>bool</type>
+      </para>
+      <para>
+       If true, the index is currently enabled and should be used for queries.
+       If false, the index is disabled and should not be used for queries,
+       but is still maintained when the table is modified. Default is true.
+      </para></entry>
+     </row>
     </tbody>
    </tgroup>
   </table>
diff --git a/doc/src/sgml/ref/alter_index.sgml b/doc/src/sgml/ref/alter_index.sgml
index 1d42d05d858..04b3b0b9bfe 100644
--- a/doc/src/sgml/ref/alter_index.sgml
+++ b/doc/src/sgml/ref/alter_index.sgml
@@ -31,6 +31,8 @@ ALTER INDEX [ IF EXISTS ] <replaceable class="parameter">name</replaceable> ALTE
     SET STATISTICS <replaceable class="parameter">integer</replaceable>
 ALTER INDEX ALL IN TABLESPACE <replaceable class="parameter">name</replaceable> [ OWNED BY <replaceable class="parameter">role_name</replaceable> [, ... ] ]
     SET TABLESPACE <replaceable class="parameter">new_tablespace</replaceable> [ NOWAIT ]
+ALTER INDEX [ IF EXISTS ] <replaceable class="parameter">name</replaceable> ENABLE
+ALTER INDEX [ IF EXISTS ] <replaceable class="parameter">name</replaceable> DISABLE
 </synopsis>
  </refsynopsisdiv>
 
@@ -159,6 +161,33 @@ ALTER INDEX ALL IN TABLESPACE <replaceable class="parameter">name</replaceable>
     </listitem>
    </varlistentry>
 
+   <varlistentry>
+    <term><literal>ENABLE</literal></term>
+    <listitem>
+     <para>
+      Enable the specified index. The index will be used by the query planner
+      for query optimization. This is the default state for newly created indexes.
+     </para>
+    </listitem>
+   </varlistentry>
+
+   <varlistentry>
+    <term><literal>DISABLE</literal></term>
+    <listitem>
+     <para>
+      Disable the specified index. A disabled index is not used by the query planner
+      for query optimization, but it is still maintained when the underlying table
+      data changes. This can be useful for testing query performance with and without
+      specific indexes, temporarily reducing the overhead of index maintenance
+      during bulk data loading operations, or verifying an index is not being used
+      before dropping it. If performance degrades after disabling an index, it can be
+      easily re-enabled. Before disabling, it's recommended to check
+      <structname>pg_stat_user_indexes</structname>.<structfield>idx_scan</structfield>
+      to identify potentially unused indexes.
+     </para>
+    </listitem>
+   </varlistentry>
+
   </variablelist>
   </para>
 
@@ -301,6 +330,20 @@ CREATE INDEX coord_idx ON measured (x, y, (z + t));
 ALTER INDEX coord_idx ALTER COLUMN 3 SET STATISTICS 1000;
 </programlisting></para>
 
+  <para>
+   To enable an index:
+<programlisting>
+ALTER INDEX idx_name ENABLE;
+</programlisting>
+  </para>
+
+  <para>
+   To disable an index:
+<programlisting>
+ALTER INDEX idx_name DISABLE;
+</programlisting>
+  </para>
+
  </refsect1>
 
  <refsect1>
diff --git a/doc/src/sgml/ref/create_index.sgml b/doc/src/sgml/ref/create_index.sgml
index 208389e8006..a7693112853 100644
--- a/doc/src/sgml/ref/create_index.sgml
+++ b/doc/src/sgml/ref/create_index.sgml
@@ -28,6 +28,7 @@ CREATE [ UNIQUE ] INDEX [ CONCURRENTLY ] [ [ IF NOT EXISTS ] <replaceable class=
     [ WITH ( <replaceable class="parameter">storage_parameter</replaceable> [= <replaceable class="parameter">value</replaceable>] [, ... ] ) ]
     [ TABLESPACE <replaceable class="parameter">tablespace_name</replaceable> ]
     [ WHERE <replaceable class="parameter">predicate</replaceable> ]
+    [ DISABLE ]
 </synopsis>
  </refsynopsisdiv>
 
@@ -380,6 +381,19 @@ CREATE [ UNIQUE ] INDEX [ CONCURRENTLY ] [ [ IF NOT EXISTS ] <replaceable class=
       </listitem>
      </varlistentry>
 
+    <varlistentry>
+      <term><literal>DISABLE</literal></term>
+      <listitem>
+       <para>
+        Creates the index in a disabled state (default enabled). A disabled index is not used by the
+        query planner for query optimization, but it is still maintained when the
+        underlying table data changes. This can be useful when you want to create
+        an index without immediately impacting query performance, allowing you to
+        enable it later at a more convenient time. The index can be enabled later
+        using <command>ALTER INDEX ... ENABLE</command>.
+       </para>
+      </listitem>
+     </varlistentry>
     </variablelist>
 
   <refsect2 id="sql-createindex-storage-parameters" xreflabel="Index Storage Parameters">
@@ -701,6 +715,14 @@ Indexes:
     partitioned index is a metadata only operation.
    </para>
 
+  <para>
+   When creating an index with the <literal>DISABLE</literal> option, the index
+   will be created but not used for query planning. This can be useful for
+   preparing an index in advance of its use, or for testing purposes. The index
+   will still be maintained as the table is modified, so it can be enabled
+   later without needing to be rebuilt. By default all new indexes are enabled.
+  </para>
+
   </refsect2>
  </refsect1>
 
@@ -980,6 +1002,13 @@ SELECT * FROM points
 CREATE INDEX CONCURRENTLY sales_quantity_index ON sales_table (quantity);
 </programlisting></para>
 
+  <para>
+   To create an index on the table <literal>test_table</literal> with the default
+   name, but have it initially disabled:
+<programlisting>
+CREATE INDEX ON test_table (col1) DISABLE;
+</programlisting>
+  </para>
  </refsect1>
 
  <refsect1>
diff --git a/src/backend/bootstrap/bootparse.y b/src/backend/bootstrap/bootparse.y
index 9833f52c1be..9eea080ab5b 100644
--- a/src/backend/bootstrap/bootparse.y
+++ b/src/backend/bootstrap/bootparse.y
@@ -303,6 +303,7 @@ Boot_DeclareIndexStmt:
 					stmt->concurrent = false;
 					stmt->if_not_exists = false;
 					stmt->reset_default_tblspc = false;
+					stmt->isenabled = true;
 
 					/* locks and races need not concern us in bootstrap mode */
 					relationId = RangeVarGetRelid(stmt->relation, NoLock,
@@ -356,6 +357,7 @@ Boot_DeclareUniqueIndexStmt:
 					stmt->concurrent = false;
 					stmt->if_not_exists = false;
 					stmt->reset_default_tblspc = false;
+					stmt->isenabled = true;
 
 					/* locks and races need not concern us in bootstrap mode */
 					relationId = RangeVarGetRelid(stmt->relation, NoLock,
diff --git a/src/backend/catalog/index.c b/src/backend/catalog/index.c
index 022b9b99b13..bb558baa5e4 100644
--- a/src/backend/catalog/index.c
+++ b/src/backend/catalog/index.c
@@ -119,7 +119,8 @@ static void UpdateIndexRelation(Oid indexoid, Oid heapoid,
 								bool isexclusion,
 								bool immediate,
 								bool isvalid,
-								bool isready);
+								bool isready,
+								bool isenabled);
 static void index_update_stats(Relation rel,
 							   bool hasindex,
 							   double reltuples);
@@ -571,7 +572,8 @@ UpdateIndexRelation(Oid indexoid,
 					bool isexclusion,
 					bool immediate,
 					bool isvalid,
-					bool isready)
+					bool isready,
+					bool isenabled)
 {
 	int2vector *indkey;
 	oidvector  *indcollation;
@@ -649,6 +651,7 @@ UpdateIndexRelation(Oid indexoid,
 	values[Anum_pg_index_indisready - 1] = BoolGetDatum(isready);
 	values[Anum_pg_index_indislive - 1] = BoolGetDatum(true);
 	values[Anum_pg_index_indisreplident - 1] = BoolGetDatum(false);
+	values[Anum_pg_index_indisenabled - 1] = BoolGetDatum(isenabled);
 	values[Anum_pg_index_indkey - 1] = PointerGetDatum(indkey);
 	values[Anum_pg_index_indcollation - 1] = PointerGetDatum(indcollation);
 	values[Anum_pg_index_indclass - 1] = PointerGetDatum(indclass);
@@ -714,6 +717,8 @@ UpdateIndexRelation(Oid indexoid,
  *			already exists.
  *		INDEX_CREATE_PARTITIONED:
  *			create a partitioned index (table must be partitioned)
+ *		INDEX_CREATE_DISABLED:
+*				create the index as disabled if instructed, defaults to being enabled.
  * constr_flags: flags passed to index_constraint_create
  *		(only if INDEX_CREATE_ADD_CONSTRAINT is set)
  * allow_system_table_mods: allow table to be a system catalog
@@ -759,6 +764,7 @@ index_create(Relation heapRelation,
 	bool		invalid = (flags & INDEX_CREATE_INVALID) != 0;
 	bool		concurrent = (flags & INDEX_CREATE_CONCURRENT) != 0;
 	bool		partitioned = (flags & INDEX_CREATE_PARTITIONED) != 0;
+	bool 		isenabled  = (flags & INDEX_CREATE_ENABLED) != 0;
 	char		relkind;
 	TransactionId relfrozenxid;
 	MultiXactId relminmxid;
@@ -1042,13 +1048,15 @@ index_create(Relation heapRelation,
 	 *	  (Or, could define a rule to maintain the predicate) --Nels, Feb '92
 	 * ----------------
 	 */
+
 	UpdateIndexRelation(indexRelationId, heapRelationId, parentIndexRelid,
 						indexInfo,
 						collationIds, opclassIds, coloptions,
 						isprimary, is_exclusion,
 						(constr_flags & INDEX_CONSTR_CREATE_DEFERRABLE) == 0,
 						!concurrent && !invalid,
-						!concurrent);
+						!concurrent,
+						isenabled);
 
 	/*
 	 * Register relcache invalidation on the indexes' heap relation, to
@@ -1317,6 +1325,8 @@ index_concurrently_create_copy(Relation heapRelation, Oid oldIndexId,
 	List	   *indexColNames = NIL;
 	List	   *indexExprs = NIL;
 	List	   *indexPreds = NIL;
+	Form_pg_index indexForm;
+	bits16 	 createFlags;
 
 	indexRelation = index_open(oldIndexId, RowExclusiveLock);
 
@@ -1344,6 +1354,9 @@ index_concurrently_create_copy(Relation heapRelation, Oid oldIndexId,
 											Anum_pg_index_indoption);
 	indcoloptions = (int2vector *) DatumGetPointer(colOptionDatum);
 
+	/* Get the enabled state of the original index */
+	indexForm = (Form_pg_index) GETSTRUCT(indexTuple);
+
 	/* Fetch reloptions of index if any */
 	classTuple = SearchSysCache1(RELOID, ObjectIdGetDatum(oldIndexId));
 	if (!HeapTupleIsValid(classTuple))
@@ -1435,6 +1448,16 @@ index_concurrently_create_copy(Relation heapRelation, Oid oldIndexId,
 		stattargets[i].isnull = isnull;
 	}
 
+	/*
+	* Determine the create flags for the new index.
+	* We always use SKIP_BUILD and CONCURRENT for concurrent reindexing.
+	* If the original index was enabled, we also set the ENABLED flag
+	* to maintain the same state in the new index.
+	*/
+	createFlags = INDEX_CREATE_SKIP_BUILD | INDEX_CREATE_CONCURRENT;
+	if (indexForm->indisenabled)
+			createFlags |= INDEX_CREATE_ENABLED;
+
 	/*
 	 * Now create the new index.
 	 *
@@ -1458,7 +1481,7 @@ index_concurrently_create_copy(Relation heapRelation, Oid oldIndexId,
 							  indcoloptions->values,
 							  stattargets,
 							  reloptionsDatum,
-							  INDEX_CREATE_SKIP_BUILD | INDEX_CREATE_CONCURRENT,
+							  createFlags,
 							  0,
 							  true, /* allow table to be a system catalog? */
 							  false,	/* is_internal? */
diff --git a/src/backend/catalog/toasting.c b/src/backend/catalog/toasting.c
index 874a8fc89ad..a612a0a3de1 100644
--- a/src/backend/catalog/toasting.c
+++ b/src/backend/catalog/toasting.c
@@ -325,7 +325,7 @@ create_toast_table(Relation rel, Oid toastOid, Oid toastIndexOid,
 				 BTREE_AM_OID,
 				 rel->rd_rel->reltablespace,
 				 collationIds, opclassIds, NULL, coloptions, NULL, (Datum) 0,
-				 INDEX_CREATE_IS_PRIMARY, 0, true, true, NULL);
+				 INDEX_CREATE_IS_PRIMARY | INDEX_CREATE_ENABLED, 0, true, true, NULL);
 
 	table_close(toast_rel, NoLock);
 
diff --git a/src/backend/commands/indexcmds.c b/src/backend/commands/indexcmds.c
index 32ff3ca9a28..c452ce07474 100644
--- a/src/backend/commands/indexcmds.c
+++ b/src/backend/commands/indexcmds.c
@@ -1228,6 +1228,10 @@ DefineIndex(Oid tableId,
 		flags |= INDEX_CREATE_PARTITIONED;
 	if (stmt->primary)
 		flags |= INDEX_CREATE_IS_PRIMARY;
+   if (stmt->isenabled)
+		flags |= INDEX_CREATE_ENABLED;
+   else
+		flags &= ~INDEX_CREATE_ENABLED;
 
 	/*
 	 * If the table is partitioned, and recursion was declined but partitions
diff --git a/src/backend/commands/tablecmds.c b/src/backend/commands/tablecmds.c
index 59156a1c1f6..3a8fa5f26e2 100644
--- a/src/backend/commands/tablecmds.c
+++ b/src/backend/commands/tablecmds.c
@@ -698,7 +698,7 @@ static List *GetParentedForeignKeyRefs(Relation partition);
 static void ATDetachCheckNoForeignKeyRefs(Relation partition);
 static char GetAttributeCompression(Oid atttypid, const char *compression);
 static char GetAttributeStorage(Oid atttypid, const char *storagemode);
-
+static void ATExecEnableDisableIndex(Relation rel, bool enable);
 
 /* ----------------------------------------------------------------
  *		DefineRelation
@@ -4664,6 +4664,8 @@ AlterTableGetLockLevel(List *cmds)
 			case AT_SetExpression:
 			case AT_DropExpression:
 			case AT_SetCompression:
+			case AT_EnableIndex:
+			case AT_DisableIndex:
 				cmd_lockmode = AccessExclusiveLock;
 				break;
 
@@ -5228,6 +5230,12 @@ ATPrepCmd(List **wqueue, Relation rel, AlterTableCmd *cmd,
 			/* No command-specific prep needed */
 			pass = AT_PASS_MISC;
 			break;
+		case AT_EnableIndex:
+		case AT_DisableIndex:
+			ATSimplePermissions(cmd->subtype, rel, ATT_INDEX | ATT_PARTITIONED_INDEX);
+			/* No command-specific prep needed */
+			pass = AT_PASS_MISC;
+			break;
 		default:				/* oops */
 			elog(ERROR, "unrecognized alter table type: %d",
 				 (int) cmd->subtype);
@@ -5624,6 +5632,12 @@ ATExecCmd(List **wqueue, AlteredTableInfo *tab,
 		case AT_DetachPartitionFinalize:
 			address = ATExecDetachPartitionFinalize(rel, ((PartitionCmd *) cmd->def)->name);
 			break;
+		case AT_EnableIndex:
+				ATExecEnableDisableIndex(rel, true);
+				break;
+		case AT_DisableIndex:
+				ATExecEnableDisableIndex(rel, false);
+				break;
 		default:				/* oops */
 			elog(ERROR, "unrecognized alter table type: %d",
 				 (int) cmd->subtype);
@@ -6518,6 +6532,8 @@ alter_table_type_to_string(AlterTableType cmdtype)
 			return "DROP COLUMN";
 		case AT_AddIndex:
 		case AT_ReAddIndex:
+		case AT_EnableIndex:
+		case AT_DisableIndex:
 			return NULL;		/* not real grammar */
 		case AT_AddConstraint:
 		case AT_ReAddConstraint:
@@ -21230,3 +21246,52 @@ GetAttributeStorage(Oid atttypid, const char *storagemode)
 
 	return cstorage;
 }
+
+/*
+ * ATExecEnableDisableIndex
+ * Performs a catalog update to enable or disable an index in pg_index.
+ */
+static void
+ATExecEnableDisableIndex(Relation rel, bool enable)
+{
+	Oid         indexOid = RelationGetRelid(rel);
+	Relation    pg_index;
+	HeapTuple   indexTuple;
+	Form_pg_index indexForm;
+	bool        updated = false;
+
+	pg_index = table_open(IndexRelationId, RowExclusiveLock);
+
+	indexTuple = SearchSysCacheCopy1(INDEXRELID, ObjectIdGetDatum(indexOid));
+	if (!HeapTupleIsValid(indexTuple))
+		elog(ERROR, "could not find tuple for index %u", indexOid);
+
+	indexForm = (Form_pg_index) GETSTRUCT(indexTuple);
+	if (indexForm->indcheckxmin)
+	{
+		heap_freetuple(indexTuple);
+		table_close(pg_index, RowExclusiveLock);
+		ereport(ERROR,
+				(errcode(ERRCODE_OBJECT_NOT_IN_PREREQUISITE_STATE),
+				errmsg("cannot enable/disable index while indcheckxmin is true"),
+				errhint("Wait for all transactions that might see inconsistent HOT chains to complete")));
+	}
+
+	if (indexForm->indisenabled != enable)
+	{
+		indexForm->indisenabled = enable;
+
+		CatalogTupleUpdate(pg_index, &indexTuple->t_self, indexTuple);
+		updated = true;
+	}
+
+	heap_freetuple(indexTuple);
+	table_close(pg_index, RowExclusiveLock);
+
+	if (updated)
+	{
+		CacheInvalidateRelcache(rel);
+		InvokeObjectPostAlterHook(IndexRelationId, indexOid, 0);
+		CommandCounterIncrement();
+	}
+}
diff --git a/src/backend/optimizer/util/plancat.c b/src/backend/optimizer/util/plancat.c
index 71abb01f655..d9f3557b403 100644
--- a/src/backend/optimizer/util/plancat.c
+++ b/src/backend/optimizer/util/plancat.c
@@ -295,6 +295,19 @@ get_relation_info(PlannerInfo *root, Oid relationObjectId, bool inhparent,
 			info->opcintype = (Oid *) palloc(sizeof(Oid) * nkeycolumns);
 			info->canreturn = (bool *) palloc(sizeof(bool) * ncolumns);
 
+			/*
+			 * Skip disabled indexes altogether, as they should not be considered
+			 * for query planning. This builds the data structure for the planner's
+			 * use and we make it part of IndexOptInfo since the index is already open.
+			 * We also close the relation before continuing to the next index.
+			 */
+			info->enabled = index->indisenabled;
+			if (!info->enabled)
+			{
+				index_close(indexRelation, NoLock);
+				continue;
+			}
+
 			for (i = 0; i < ncolumns; i++)
 			{
 				info->indexkeys[i] = index->indkey.values[i];
diff --git a/src/backend/parser/gram.y b/src/backend/parser/gram.y
index 271ae26cbaf..20562dd258e 100644
--- a/src/backend/parser/gram.y
+++ b/src/backend/parser/gram.y
@@ -324,7 +324,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 %type <ival>	add_drop opt_asc_desc opt_nulls_order
 
 %type <node>	alter_table_cmd alter_type_cmd opt_collate_clause
-	   replica_identity partition_cmd index_partition_cmd
+	   replica_identity partition_cmd index_partition_cmd index_alter_cmd
 %type <list>	alter_table_cmds alter_type_cmds
 %type <list>    alter_identity_column_option_list
 %type <defelt>  alter_identity_column_option
@@ -491,6 +491,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 %type <boolean> opt_unique opt_verbose opt_full
 %type <boolean> opt_freeze opt_analyze opt_default
 %type <defelt>	opt_binary copy_delimiter
+%type <boolean>  opt_index_enabled
 
 %type <boolean> copy_from opt_program
 
@@ -2157,6 +2158,24 @@ AlterTableStmt:
 					n->nowait = $13;
 					$$ = (Node *) n;
 				}
+		| ALTER INDEX qualified_name index_alter_cmd
+				{
+					AlterTableStmt *n = makeNode(AlterTableStmt);
+					n->relation = $3;
+					n->cmds = list_make1($4);
+					n->objtype = OBJECT_INDEX;
+					n->missing_ok = false;
+					$$ = (Node *) n;
+				}
+		| ALTER INDEX IF_P EXISTS qualified_name index_alter_cmd
+				{
+					AlterTableStmt *n = makeNode(AlterTableStmt);
+					n->relation = $5;
+					n->cmds = list_make1($6);
+					n->objtype = OBJECT_INDEX;
+					n->missing_ok = true;
+					$$ = (Node *) n;
+				}
 		|	ALTER INDEX qualified_name alter_table_cmds
 				{
 					AlterTableStmt *n = makeNode(AlterTableStmt);
@@ -2382,6 +2401,21 @@ index_partition_cmd:
 				}
 		;
 
+index_alter_cmd:
+		/* ALTER INDEX <name> ENABLE|DISABLE */
+		ENABLE_P
+			{
+				AlterTableCmd *n = makeNode(AlterTableCmd);
+				n->subtype = AT_EnableIndex;
+				$$ = (Node *) n;
+			}
+		| DISABLE_P
+			{
+				AlterTableCmd *n = makeNode(AlterTableCmd);
+				n->subtype = AT_DisableIndex;
+				$$ = (Node *) n;
+			}
+		;
 alter_table_cmd:
 			/* ALTER TABLE <name> ADD <coldef> */
 			ADD_P columnDef
@@ -8195,7 +8229,7 @@ defacl_privilege_target:
 
 IndexStmt:	CREATE opt_unique INDEX opt_concurrently opt_single_name
 			ON relation_expr access_method_clause '(' index_params ')'
-			opt_include opt_unique_null_treatment opt_reloptions OptTableSpace where_clause
+			opt_include opt_unique_null_treatment opt_reloptions OptTableSpace where_clause opt_index_enabled
 				{
 					IndexStmt *n = makeNode(IndexStmt);
 
@@ -8210,6 +8244,7 @@ IndexStmt:	CREATE opt_unique INDEX opt_concurrently opt_single_name
 					n->options = $14;
 					n->tableSpace = $15;
 					n->whereClause = $16;
+					n->isenabled = $17;
 					n->excludeOpNames = NIL;
 					n->idxcomment = NULL;
 					n->indexOid = InvalidOid;
@@ -8227,7 +8262,7 @@ IndexStmt:	CREATE opt_unique INDEX opt_concurrently opt_single_name
 				}
 			| CREATE opt_unique INDEX opt_concurrently IF_P NOT EXISTS name
 			ON relation_expr access_method_clause '(' index_params ')'
-			opt_include opt_unique_null_treatment opt_reloptions OptTableSpace where_clause
+			opt_include opt_unique_null_treatment opt_reloptions OptTableSpace where_clause opt_index_enabled
 				{
 					IndexStmt *n = makeNode(IndexStmt);
 
@@ -8242,6 +8277,7 @@ IndexStmt:	CREATE opt_unique INDEX opt_concurrently opt_single_name
 					n->options = $17;
 					n->tableSpace = $18;
 					n->whereClause = $19;
+					n->isenabled = $20;
 					n->excludeOpNames = NIL;
 					n->idxcomment = NULL;
 					n->indexOid = InvalidOid;
@@ -8264,6 +8300,12 @@ opt_unique:
 			| /*EMPTY*/								{ $$ = false; }
 		;
 
+opt_index_enabled:
+			ENABLE_P                      { $$ = true; }
+			| DISABLE_P                   { $$ = false; }
+			| /*EMPTY*/                 	{ $$ = true; }
+		;
+
 access_method_clause:
 			USING name								{ $$ = $2; }
 			| /*EMPTY*/								{ $$ = DEFAULT_INDEX_TYPE; }
diff --git a/src/backend/parser/parse_utilcmd.c b/src/backend/parser/parse_utilcmd.c
index abbe1bb45a3..1c0ca0fa8d1 100644
--- a/src/backend/parser/parse_utilcmd.c
+++ b/src/backend/parser/parse_utilcmd.c
@@ -1759,6 +1759,7 @@ generateClonedIndexStmt(RangeVar *heapRel, Relation source_idx,
 	index->concurrent = false;
 	index->if_not_exists = false;
 	index->reset_default_tblspc = false;
+	index->isenabled = idxrec->indisenabled;
 
 	/*
 	 * We don't try to preserve the name of the source index; instead, just
@@ -2380,6 +2381,8 @@ transformIndexConstraint(Constraint *constraint, CreateStmtContext *cxt)
 	index->concurrent = false;
 	index->if_not_exists = false;
 	index->reset_default_tblspc = constraint->reset_default_tblspc;
+	/* Ensure indexes for constraints are created as enabled by default */
+	index->isenabled = true;
 
 	/*
 	 * If it's ALTER TABLE ADD CONSTRAINT USING INDEX, look up the index and
diff --git a/src/backend/utils/adt/ruleutils.c b/src/backend/utils/adt/ruleutils.c
index d11a8a20eea..73cb14ad443 100644
--- a/src/backend/utils/adt/ruleutils.c
+++ b/src/backend/utils/adt/ruleutils.c
@@ -1562,6 +1562,10 @@ pg_get_indexdef_worker(Oid indexrelid, int colno,
 			else
 				appendStringInfo(&buf, " WHERE %s", str);
 		}
+
+		/* Add DISABLE clause if the index is disabled */
+		if (!idxrec->indisenabled)
+				appendStringInfoString(&buf, " DISABLE");
 	}
 
 	/* Clean up */
diff --git a/src/backend/utils/cache/relcache.c b/src/backend/utils/cache/relcache.c
index d1ae761b3f6..ce45a7633f1 100644
--- a/src/backend/utils/cache/relcache.c
+++ b/src/backend/utils/cache/relcache.c
@@ -2315,6 +2315,7 @@ RelationReloadIndexInfo(Relation relation)
 		relation->rd_index->indisready = index->indisready;
 		relation->rd_index->indislive = index->indislive;
 		relation->rd_index->indisreplident = index->indisreplident;
+		relation->rd_index->indisenabled = index->indisenabled;
 
 		/* Copy xmin too, as that is needed to make sense of indcheckxmin */
 		HeapTupleHeaderSetXmin(relation->rd_indextuple->t_data,
diff --git a/src/include/catalog/index.h b/src/include/catalog/index.h
index 4daa8bef5ee..50cd53c64e5 100644
--- a/src/include/catalog/index.h
+++ b/src/include/catalog/index.h
@@ -65,6 +65,7 @@ extern void index_check_primary_key(Relation heapRel,
 #define	INDEX_CREATE_IF_NOT_EXISTS			(1 << 4)
 #define	INDEX_CREATE_PARTITIONED			(1 << 5)
 #define INDEX_CREATE_INVALID				(1 << 6)
+#define INDEX_CREATE_ENABLED        (1 << 7)
 
 extern Oid	index_create(Relation heapRelation,
 						 const char *indexRelationName,
@@ -175,7 +176,6 @@ extern void RestoreReindexState(const void *reindexstate);
 
 extern void IndexSetParentIndex(Relation partitionIdx, Oid parentOid);
 
-
 /*
  * itemptr_encode - Encode ItemPointer as int64/int8
  *
diff --git a/src/include/catalog/pg_index.h b/src/include/catalog/pg_index.h
index 4392b9d221d..766a52193cb 100644
--- a/src/include/catalog/pg_index.h
+++ b/src/include/catalog/pg_index.h
@@ -44,6 +44,7 @@ CATALOG(pg_index,2610,IndexRelationId) BKI_SCHEMA_MACRO
 	bool		indisready;		/* is this index ready for inserts? */
 	bool		indislive;		/* is this index alive at all? */
 	bool		indisreplident; /* is this index the identity for replication? */
+	bool		indisenabled;	/* is this index enabled for use by queries? */
 
 	/* variable-length fields start here, but we allow direct access to indkey */
 	int2vector	indkey BKI_FORCE_NOT_NULL;	/* column numbers of indexed cols,
diff --git a/src/include/nodes/parsenodes.h b/src/include/nodes/parsenodes.h
index 23c9e3c5abf..d1c4df1bf79 100644
--- a/src/include/nodes/parsenodes.h
+++ b/src/include/nodes/parsenodes.h
@@ -2467,6 +2467,8 @@ typedef enum AlterTableType
 	AT_SetIdentity,				/* SET identity column options */
 	AT_DropIdentity,			/* DROP IDENTITY */
 	AT_ReAddStatistics,			/* internal to commands/tablecmds.c */
+	AT_EnableIndex,					/* ENABLE INDEX */
+	AT_DisableIndex,				/* DISABLE INDEX */
 } AlterTableType;
 
 typedef struct AlterTableCmd	/* one subcommand of an ALTER TABLE */
@@ -3463,6 +3465,7 @@ typedef struct IndexStmt
 	bool		if_not_exists;	/* just do nothing if index already exists? */
 	bool		reset_default_tblspc;	/* reset default_tablespace prior to
 										 * executing */
+  bool		isenabled;		/* true if ENABLE (default), false if DISABLE */
 } IndexStmt;
 
 /* ----------------------
diff --git a/src/include/nodes/pathnodes.h b/src/include/nodes/pathnodes.h
index fbf05322c75..9e9d9d4cb61 100644
--- a/src/include/nodes/pathnodes.h
+++ b/src/include/nodes/pathnodes.h
@@ -1236,6 +1236,8 @@ struct IndexOptInfo
 	/* AM's cost estimator */
 	/* Rather than include amapi.h here, we declare amcostestimate like this */
 	void		(*amcostestimate) (struct PlannerInfo *, struct IndexPath *, double, Cost *, Cost *, Selectivity *, double *, double *) pg_node_attr(read_write_ignore);
+	/* true if this index is enabled */
+	bool		enabled;
 };
 
 /*
diff --git a/src/test/regress/expected/create_index.out b/src/test/regress/expected/create_index.out
index bd5f002cf20..bf6c9b688dd 100644
--- a/src/test/regress/expected/create_index.out
+++ b/src/test/regress/expected/create_index.out
@@ -3363,6 +3363,511 @@ ERROR:  REINDEX SCHEMA cannot run inside a transaction block
 END;
 -- concurrently
 REINDEX SCHEMA CONCURRENTLY schema_to_reindex;
+-- Test enable/disable functionality for indexes
+CREATE TABLE index_test(
+    id INT PRIMARY KEY,
+    data TEXT,
+    num INT,
+    vector INT[],
+    range INT4RANGE
+);
+INSERT INTO index_test
+SELECT
+    g,
+    'data ' || g,
+    g % 100,
+    ARRAY[g, g+1, g+2],
+    int4range(g, g+10)
+FROM generate_series(1, 1000) g;
+-- Function for testing
+CREATE FUNCTION get_data_length(text) RETURNS INT AS $$
+    SELECT length($1);
+$$ LANGUAGE SQL IMMUTABLE;
+-- Helper function to show index status
+CREATE OR REPLACE FUNCTION show_index_status(index_name text)
+RETURNS TABLE (
+    indexrelid regclass,
+    indisvalid boolean,
+    indisready boolean,
+    indislive boolean,
+    indisenabled boolean
+) AS $$
+BEGIN
+    RETURN QUERY EXECUTE format('
+        SELECT indexrelid::regclass, indisvalid, indisready, indislive, indisenabled
+        FROM pg_index
+        WHERE indexrelid = %L::regclass', index_name);
+END;
+$$ LANGUAGE plpgsql;
+-- Create and test each index type
+-- 1. Basic single-column index
+CREATE INDEX idx_single ON index_test(data);
+SELECT show_index_status('idx_single');
+  show_index_status   
+----------------------
+ (idx_single,t,t,t,t)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE data = 'data 500';
+                  QUERY PLAN                   
+-----------------------------------------------
+ Bitmap Heap Scan on index_test
+   Recheck Cond: (data = 'data 500'::text)
+   ->  Bitmap Index Scan on idx_single
+         Index Cond: (data = 'data 500'::text)
+(4 rows)
+
+ALTER INDEX idx_single DISABLE;
+SELECT show_index_status('idx_single');
+  show_index_status   
+----------------------
+ (idx_single,t,t,t,f)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE data = 'data 500';
+             QUERY PLAN              
+-------------------------------------
+ Seq Scan on index_test
+   Filter: (data = 'data 500'::text)
+(2 rows)
+
+ALTER INDEX idx_single ENABLE;
+SELECT show_index_status('idx_single');
+  show_index_status   
+----------------------
+ (idx_single,t,t,t,t)
+(1 row)
+
+-- 2. Multi-column index
+CREATE INDEX idx_multi ON index_test(num, data);
+SELECT show_index_status('idx_multi');
+  show_index_status  
+---------------------
+ (idx_multi,t,t,t,t)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE num = 50 AND data > 'data 500';
+                           QUERY PLAN                           
+----------------------------------------------------------------
+ Bitmap Heap Scan on index_test
+   Recheck Cond: ((num = 50) AND (data > 'data 500'::text))
+   ->  Bitmap Index Scan on idx_multi
+         Index Cond: ((num = 50) AND (data > 'data 500'::text))
+(4 rows)
+
+ALTER INDEX idx_multi DISABLE;
+SELECT show_index_status('idx_multi');
+  show_index_status  
+---------------------
+ (idx_multi,t,t,t,f)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE num = 50 AND data > 'data 500';
+                      QUERY PLAN                      
+------------------------------------------------------
+ Seq Scan on index_test
+   Filter: ((data > 'data 500'::text) AND (num = 50))
+(2 rows)
+
+ALTER INDEX idx_multi ENABLE;
+SELECT show_index_status('idx_multi');
+  show_index_status  
+---------------------
+ (idx_multi,t,t,t,t)
+(1 row)
+
+-- 3. Partial index
+CREATE INDEX idx_partial ON index_test(num) WHERE num < 50;
+SELECT show_index_status('idx_partial');
+   show_index_status   
+-----------------------
+ (idx_partial,t,t,t,t)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE num = 25;
+               QUERY PLAN               
+----------------------------------------
+ Bitmap Heap Scan on index_test
+   Recheck Cond: (num = 25)
+   ->  Bitmap Index Scan on idx_partial
+         Index Cond: (num = 25)
+(4 rows)
+
+ALTER INDEX idx_partial DISABLE;
+SELECT show_index_status('idx_partial');
+   show_index_status   
+-----------------------
+ (idx_partial,t,t,t,f)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE num = 25;
+              QUERY PLAN              
+--------------------------------------
+ Bitmap Heap Scan on index_test
+   Recheck Cond: (num = 25)
+   ->  Bitmap Index Scan on idx_multi
+         Index Cond: (num = 25)
+(4 rows)
+
+ALTER INDEX idx_partial ENABLE;
+SELECT show_index_status('idx_partial');
+   show_index_status   
+-----------------------
+ (idx_partial,t,t,t,t)
+(1 row)
+
+-- 4. Expression index
+CREATE INDEX idx_expression ON index_test((lower(data)));
+SELECT show_index_status('idx_expression');
+    show_index_status     
+--------------------------
+ (idx_expression,t,t,t,t)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE lower(data) = 'data 500';
+                      QUERY PLAN                      
+------------------------------------------------------
+ Bitmap Heap Scan on index_test
+   Recheck Cond: (lower(data) = 'data 500'::text)
+   ->  Bitmap Index Scan on idx_expression
+         Index Cond: (lower(data) = 'data 500'::text)
+(4 rows)
+
+ALTER INDEX idx_expression DISABLE;
+SELECT show_index_status('idx_expression');
+    show_index_status     
+--------------------------
+ (idx_expression,t,t,t,f)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE lower(data) = 'data 500';
+                 QUERY PLAN                 
+--------------------------------------------
+ Seq Scan on index_test
+   Filter: (lower(data) = 'data 500'::text)
+(2 rows)
+
+ALTER INDEX idx_expression ENABLE;
+SELECT show_index_status('idx_expression');
+    show_index_status     
+--------------------------
+ (idx_expression,t,t,t,t)
+(1 row)
+
+-- 5. GIN index
+CREATE INDEX idx_gin ON index_test USING gin(vector);
+SELECT show_index_status('idx_gin');
+ show_index_status 
+-------------------
+ (idx_gin,t,t,t,t)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE vector @> ARRAY[500];
+                     QUERY PLAN                     
+----------------------------------------------------
+ Bitmap Heap Scan on index_test
+   Recheck Cond: (vector @> '{500}'::integer[])
+   ->  Bitmap Index Scan on idx_gin
+         Index Cond: (vector @> '{500}'::integer[])
+(4 rows)
+
+ALTER INDEX idx_gin DISABLE;
+SELECT show_index_status('idx_gin');
+ show_index_status 
+-------------------
+ (idx_gin,t,t,t,f)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE vector @> ARRAY[500];
+                QUERY PLAN                
+------------------------------------------
+ Seq Scan on index_test
+   Filter: (vector @> '{500}'::integer[])
+(2 rows)
+
+ALTER INDEX idx_gin ENABLE;
+SELECT show_index_status('idx_gin');
+ show_index_status 
+-------------------
+ (idx_gin,t,t,t,t)
+(1 row)
+
+-- 6. GiST index
+CREATE INDEX idx_gist ON index_test USING gist(range);
+SELECT show_index_status('idx_gist');
+ show_index_status  
+--------------------
+ (idx_gist,t,t,t,t)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE range && int4range(100, 110);
+                      QUERY PLAN                       
+-------------------------------------------------------
+ Bitmap Heap Scan on index_test
+   Recheck Cond: (range && '[100,110)'::int4range)
+   ->  Bitmap Index Scan on idx_gist
+         Index Cond: (range && '[100,110)'::int4range)
+(4 rows)
+
+ALTER INDEX idx_gist DISABLE;
+SELECT show_index_status('idx_gist');
+ show_index_status  
+--------------------
+ (idx_gist,t,t,t,f)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE range && int4range(100, 110);
+                 QUERY PLAN                  
+---------------------------------------------
+ Seq Scan on index_test
+   Filter: (range && '[100,110)'::int4range)
+(2 rows)
+
+ALTER INDEX idx_gist ENABLE;
+SELECT show_index_status('idx_gist');
+ show_index_status  
+--------------------
+ (idx_gist,t,t,t,t)
+(1 row)
+
+-- 7. Covering index
+CREATE INDEX idx_covering ON index_test(num) INCLUDE (data);
+SELECT show_index_status('idx_covering');
+   show_index_status    
+------------------------
+ (idx_covering,t,t,t,t)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT num, data FROM index_test WHERE num = 50;
+               QUERY PLAN                
+-----------------------------------------
+ Bitmap Heap Scan on index_test
+   Recheck Cond: (num = 50)
+   ->  Bitmap Index Scan on idx_covering
+         Index Cond: (num = 50)
+(4 rows)
+
+ALTER INDEX idx_covering DISABLE;
+SELECT show_index_status('idx_covering');
+   show_index_status    
+------------------------
+ (idx_covering,t,t,t,f)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT num, data FROM index_test WHERE num = 50;
+              QUERY PLAN              
+--------------------------------------
+ Bitmap Heap Scan on index_test
+   Recheck Cond: (num = 50)
+   ->  Bitmap Index Scan on idx_multi
+         Index Cond: (num = 50)
+(4 rows)
+
+ALTER INDEX idx_covering ENABLE;
+SELECT show_index_status('idx_covering');
+   show_index_status    
+------------------------
+ (idx_covering,t,t,t,t)
+(1 row)
+
+-- 8. Unique index
+CREATE UNIQUE INDEX idx_unique ON index_test(id, data);
+SELECT show_index_status('idx_unique');
+  show_index_status   
+----------------------
+ (idx_unique,t,t,t,t)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE id = 500 AND data = 'data 500';
+                        QUERY PLAN                        
+----------------------------------------------------------
+ Index Scan using idx_unique on index_test
+   Index Cond: ((id = 500) AND (data = 'data 500'::text))
+(2 rows)
+
+ALTER INDEX idx_unique DISABLE;
+SELECT show_index_status('idx_unique');
+  show_index_status   
+----------------------
+ (idx_unique,t,t,t,f)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE id = 500 AND data = 'data 500';
+                   QUERY PLAN                   
+------------------------------------------------
+ Index Scan using index_test_pkey on index_test
+   Index Cond: (id = 500)
+   Filter: (data = 'data 500'::text)
+(3 rows)
+
+ALTER INDEX idx_unique ENABLE;
+SELECT show_index_status('idx_unique');
+  show_index_status   
+----------------------
+ (idx_unique,t,t,t,t)
+(1 row)
+
+-- 9. Function-based index
+CREATE INDEX idx_func ON index_test(get_data_length(data));
+SELECT show_index_status('idx_func');
+ show_index_status  
+--------------------
+ (idx_func,t,t,t,t)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE get_data_length(data) = 10;
+               QUERY PLAN                
+-----------------------------------------
+ Bitmap Heap Scan on index_test
+   Recheck Cond: (length(data) = 10)
+   ->  Bitmap Index Scan on idx_func
+         Index Cond: (length(data) = 10)
+(4 rows)
+
+ALTER INDEX idx_func DISABLE;
+SELECT show_index_status('idx_func');
+ show_index_status  
+--------------------
+ (idx_func,t,t,t,f)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE get_data_length(data) = 10;
+          QUERY PLAN           
+-------------------------------
+ Seq Scan on index_test
+   Filter: (length(data) = 10)
+(2 rows)
+
+ALTER INDEX idx_func ENABLE;
+SELECT show_index_status('idx_func');
+ show_index_status  
+--------------------
+ (idx_func,t,t,t,t)
+(1 row)
+
+-- 10. Join index
+CREATE TABLE join_test (id INT PRIMARY KEY, ref_id INT);
+INSERT INTO join_test SELECT g, g % 100 FROM generate_series(1, 1000) g;
+CREATE INDEX idx_join ON join_test(ref_id);
+SELECT show_index_status('idx_join');
+ show_index_status  
+--------------------
+ (idx_join,t,t,t,t)
+(1 row)
+
+EXPLAIN (COSTS OFF)
+SELECT jt.id, it.data
+FROM join_test jt
+JOIN index_test it ON jt.ref_id = it.num
+WHERE jt.id BETWEEN 100 AND 200;
+                          QUERY PLAN                           
+---------------------------------------------------------------
+ Hash Join
+   Hash Cond: (it.num = jt.ref_id)
+   ->  Seq Scan on index_test it
+   ->  Hash
+         ->  Bitmap Heap Scan on join_test jt
+               Recheck Cond: ((id >= 100) AND (id <= 200))
+               ->  Bitmap Index Scan on join_test_pkey
+                     Index Cond: ((id >= 100) AND (id <= 200))
+(8 rows)
+
+-- Disable all indexes to force seq scan
+ALTER INDEX idx_join DISABLE;
+ALTER INDEX join_test_pkey DISABLE;
+SELECT show_index_status('idx_join');
+ show_index_status  
+--------------------
+ (idx_join,t,t,t,f)
+(1 row)
+
+SELECT show_index_status('join_test_pkey');
+    show_index_status     
+--------------------------
+ (join_test_pkey,t,t,t,f)
+(1 row)
+
+EXPLAIN (COSTS OFF)
+SELECT jt.id, it.data
+FROM join_test jt
+JOIN index_test it ON jt.ref_id = it.num
+WHERE jt.id BETWEEN 100 AND 200;
+                     QUERY PLAN                      
+-----------------------------------------------------
+ Hash Join
+   Hash Cond: (it.num = jt.ref_id)
+   ->  Seq Scan on index_test it
+   ->  Hash
+         ->  Seq Scan on join_test jt
+               Filter: ((id >= 100) AND (id <= 200))
+(6 rows)
+
+ALTER INDEX idx_join ENABLE;
+ALTER INDEX join_test_pkey ENABLE;
+SELECT show_index_status('idx_join');
+ show_index_status  
+--------------------
+ (idx_join,t,t,t,t)
+(1 row)
+
+SELECT show_index_status('join_test_pkey');
+    show_index_status     
+--------------------------
+ (join_test_pkey,t,t,t,t)
+(1 row)
+
+-- Test REINDEX CONCURRENTLY
+REINDEX INDEX CONCURRENTLY idx_join;
+SELECT show_index_status('idx_join');
+ show_index_status  
+--------------------
+ (idx_join,t,t,t,t)
+(1 row)
+
+ALTER INDEX idx_join DISABLE;
+SELECT show_index_status('idx_join');
+ show_index_status  
+--------------------
+ (idx_join,t,t,t,f)
+(1 row)
+
+REINDEX INDEX CONCURRENTLY idx_join;
+SELECT show_index_status('idx_join');
+ show_index_status  
+--------------------
+ (idx_join,t,t,t,f)
+(1 row)
+
+SELECT pg_get_indexdef('idx_join'::regclass);
+                                  pg_get_indexdef                                  
+-----------------------------------------------------------------------------------
+ CREATE INDEX idx_join ON schema_to_reindex.join_test USING btree (ref_id) DISABLE
+(1 row)
+
+ALTER INDEX idx_join ENABLE;
+SELECT pg_get_indexdef('idx_join'::regclass);
+                              pg_get_indexdef                              
+---------------------------------------------------------------------------
+ CREATE INDEX idx_join ON schema_to_reindex.join_test USING btree (ref_id)
+(1 row)
+
+-- Test enable/disable index with indcheckxmin being true
+CREATE TABLE indcheckxmin_test(id int PRIMARY KEY);
+INSERT INTO indcheckxmin_test VALUES (1), (2), (3);
+CREATE INDEX CONCURRENTLY idx_checkxmin ON indcheckxmin_test(id);
+BEGIN;
+-- Simulate indcheckxmin being true
+UPDATE pg_index SET indcheckxmin = true WHERE indexrelid = 'idx_checkxmin'::regclass;
+ALTER INDEX idx_checkxmin DISABLE;  -- expect fail
+ERROR:  cannot enable/disable index while indcheckxmin is true
+HINT:  Wait for all transactions that might see inconsistent HOT chains to complete
+ROLLBACK;
+-- Clean up
+DROP TABLE index_test;
+DROP TABLE join_test;
+DROP FUNCTION get_data_length;
+DROP FUNCTION show_index_status;
+DROP TABLE indcheckxmin_test CASCADE;
 -- Failure for unauthorized user
 CREATE ROLE regress_reindexuser NOLOGIN;
 SET SESSION ROLE regress_reindexuser;
diff --git a/src/test/regress/sql/create_index.sql b/src/test/regress/sql/create_index.sql
index be570da08a0..a05fddcbeca 100644
--- a/src/test/regress/sql/create_index.sql
+++ b/src/test/regress/sql/create_index.sql
@@ -1424,6 +1424,198 @@ END;
 -- concurrently
 REINDEX SCHEMA CONCURRENTLY schema_to_reindex;
 
+-- Test enable/disable functionality for indexes
+
+CREATE TABLE index_test(
+    id INT PRIMARY KEY,
+    data TEXT,
+    num INT,
+    vector INT[],
+    range INT4RANGE
+);
+
+INSERT INTO index_test
+SELECT
+    g,
+    'data ' || g,
+    g % 100,
+    ARRAY[g, g+1, g+2],
+    int4range(g, g+10)
+FROM generate_series(1, 1000) g;
+
+-- Function for testing
+CREATE FUNCTION get_data_length(text) RETURNS INT AS $$
+    SELECT length($1);
+$$ LANGUAGE SQL IMMUTABLE;
+
+-- Helper function to show index status
+CREATE OR REPLACE FUNCTION show_index_status(index_name text)
+RETURNS TABLE (
+    indexrelid regclass,
+    indisvalid boolean,
+    indisready boolean,
+    indislive boolean,
+    indisenabled boolean
+) AS $$
+BEGIN
+    RETURN QUERY EXECUTE format('
+        SELECT indexrelid::regclass, indisvalid, indisready, indislive, indisenabled
+        FROM pg_index
+        WHERE indexrelid = %L::regclass', index_name);
+END;
+$$ LANGUAGE plpgsql;
+
+-- Create and test each index type
+-- 1. Basic single-column index
+CREATE INDEX idx_single ON index_test(data);
+SELECT show_index_status('idx_single');
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE data = 'data 500';
+ALTER INDEX idx_single DISABLE;
+SELECT show_index_status('idx_single');
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE data = 'data 500';
+ALTER INDEX idx_single ENABLE;
+SELECT show_index_status('idx_single');
+
+-- 2. Multi-column index
+CREATE INDEX idx_multi ON index_test(num, data);
+SELECT show_index_status('idx_multi');
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE num = 50 AND data > 'data 500';
+ALTER INDEX idx_multi DISABLE;
+SELECT show_index_status('idx_multi');
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE num = 50 AND data > 'data 500';
+ALTER INDEX idx_multi ENABLE;
+SELECT show_index_status('idx_multi');
+
+-- 3. Partial index
+CREATE INDEX idx_partial ON index_test(num) WHERE num < 50;
+SELECT show_index_status('idx_partial');
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE num = 25;
+ALTER INDEX idx_partial DISABLE;
+SELECT show_index_status('idx_partial');
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE num = 25;
+ALTER INDEX idx_partial ENABLE;
+SELECT show_index_status('idx_partial');
+
+-- 4. Expression index
+CREATE INDEX idx_expression ON index_test((lower(data)));
+SELECT show_index_status('idx_expression');
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE lower(data) = 'data 500';
+ALTER INDEX idx_expression DISABLE;
+SELECT show_index_status('idx_expression');
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE lower(data) = 'data 500';
+ALTER INDEX idx_expression ENABLE;
+SELECT show_index_status('idx_expression');
+
+-- 5. GIN index
+CREATE INDEX idx_gin ON index_test USING gin(vector);
+SELECT show_index_status('idx_gin');
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE vector @> ARRAY[500];
+ALTER INDEX idx_gin DISABLE;
+SELECT show_index_status('idx_gin');
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE vector @> ARRAY[500];
+ALTER INDEX idx_gin ENABLE;
+SELECT show_index_status('idx_gin');
+
+-- 6. GiST index
+CREATE INDEX idx_gist ON index_test USING gist(range);
+SELECT show_index_status('idx_gist');
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE range && int4range(100, 110);
+ALTER INDEX idx_gist DISABLE;
+SELECT show_index_status('idx_gist');
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE range && int4range(100, 110);
+ALTER INDEX idx_gist ENABLE;
+SELECT show_index_status('idx_gist');
+
+-- 7. Covering index
+CREATE INDEX idx_covering ON index_test(num) INCLUDE (data);
+SELECT show_index_status('idx_covering');
+EXPLAIN (COSTS OFF) SELECT num, data FROM index_test WHERE num = 50;
+ALTER INDEX idx_covering DISABLE;
+SELECT show_index_status('idx_covering');
+EXPLAIN (COSTS OFF) SELECT num, data FROM index_test WHERE num = 50;
+ALTER INDEX idx_covering ENABLE;
+SELECT show_index_status('idx_covering');
+
+-- 8. Unique index
+CREATE UNIQUE INDEX idx_unique ON index_test(id, data);
+SELECT show_index_status('idx_unique');
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE id = 500 AND data = 'data 500';
+ALTER INDEX idx_unique DISABLE;
+SELECT show_index_status('idx_unique');
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE id = 500 AND data = 'data 500';
+ALTER INDEX idx_unique ENABLE;
+SELECT show_index_status('idx_unique');
+
+-- 9. Function-based index
+CREATE INDEX idx_func ON index_test(get_data_length(data));
+SELECT show_index_status('idx_func');
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE get_data_length(data) = 10;
+ALTER INDEX idx_func DISABLE;
+SELECT show_index_status('idx_func');
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE get_data_length(data) = 10;
+ALTER INDEX idx_func ENABLE;
+SELECT show_index_status('idx_func');
+
+-- 10. Join index
+CREATE TABLE join_test (id INT PRIMARY KEY, ref_id INT);
+INSERT INTO join_test SELECT g, g % 100 FROM generate_series(1, 1000) g;
+CREATE INDEX idx_join ON join_test(ref_id);
+SELECT show_index_status('idx_join');
+
+EXPLAIN (COSTS OFF)
+SELECT jt.id, it.data
+FROM join_test jt
+JOIN index_test it ON jt.ref_id = it.num
+WHERE jt.id BETWEEN 100 AND 200;
+
+-- Disable all indexes to force seq scan
+ALTER INDEX idx_join DISABLE;
+ALTER INDEX join_test_pkey DISABLE;
+SELECT show_index_status('idx_join');
+SELECT show_index_status('join_test_pkey');
+
+EXPLAIN (COSTS OFF)
+SELECT jt.id, it.data
+FROM join_test jt
+JOIN index_test it ON jt.ref_id = it.num
+WHERE jt.id BETWEEN 100 AND 200;
+
+ALTER INDEX idx_join ENABLE;
+ALTER INDEX join_test_pkey ENABLE;
+SELECT show_index_status('idx_join');
+SELECT show_index_status('join_test_pkey');
+
+-- Test REINDEX CONCURRENTLY
+REINDEX INDEX CONCURRENTLY idx_join;
+SELECT show_index_status('idx_join');
+
+ALTER INDEX idx_join DISABLE;
+SELECT show_index_status('idx_join');
+REINDEX INDEX CONCURRENTLY idx_join;
+SELECT show_index_status('idx_join');
+
+SELECT pg_get_indexdef('idx_join'::regclass);
+ALTER INDEX idx_join ENABLE;
+SELECT pg_get_indexdef('idx_join'::regclass);
+
+-- Test enable/disable index with indcheckxmin being true
+
+CREATE TABLE indcheckxmin_test(id int PRIMARY KEY);
+INSERT INTO indcheckxmin_test VALUES (1), (2), (3);
+CREATE INDEX CONCURRENTLY idx_checkxmin ON indcheckxmin_test(id);
+BEGIN;
+-- Simulate indcheckxmin being true
+UPDATE pg_index SET indcheckxmin = true WHERE indexrelid = 'idx_checkxmin'::regclass;
+ALTER INDEX idx_checkxmin DISABLE;  -- expect fail
+ROLLBACK;
+
+-- Clean up
+DROP TABLE index_test;
+DROP TABLE join_test;
+DROP FUNCTION get_data_length;
+DROP FUNCTION show_index_status;
+DROP TABLE indcheckxmin_test CASCADE;
+
 -- Failure for unauthorized user
 CREATE ROLE regress_reindexuser NOLOGIN;
 SET SESSION ROLE regress_reindexuser;
-- 
2.39.5 (Apple Git-154)

#75Shayon Mukherjee
shayonj@gmail.com
In reply to: Shayon Mukherjee (#74)
Re: Proposal to Enable/Disable Index using ALTER INDEX (with patch)

Hi Hackers,

Just leaving a quick note: I know this patch has through a lot of variations. I am keen on shipping this for v18 if possible, and while it’s a learning process for me, I am more than happy to iterate on any feedback. Let me know if there is anything I can do to help to keep the momentum going on this (absolutely no rush however). Just seeking feedback :).

Thank you
Shayon

Show quoted text

On Mar 7, 2025, at 2:21 AM, Shayon Mukherjee <shayonj@gmail.com> wrote:

On Sun, Feb 23, 2025 at 3:41 PM Shayon Mukherjee <shayonj@gmail.com <mailto:shayonj@gmail.com>> wrote:

I have rebased the patch on top of master (resolving some merge conflicts), along with the meson changes (thank you for that).

Rebased against the latest master and attaching the v13 patch.

Thank you
Shayon
<v13-0001-Introduce-the-ability-to-enable-disable-indexes-.patch>

#76Sami Imseih
samimseih@gmail.com
In reply to: Shayon Mukherjee (#75)
1 attachment(s)
Re: Proposal to Enable/Disable Index using ALTER INDEX (with patch)

I went back to look at this patch and a few things. I noticed it did
not have correct
indentation, so I ran pgindent. I also removed some extra lines added and made
some slight adjustments to the docs. Attached my edited patch as a txt. If you
agree, please revise into a v14.

I also noticed that between v12 and v13, the GUC use_invisible_index
was removed,
but I don't see a discussion as to why. I feel it's a good GUC to have
[0]: /messages/by-id/CAA5RZ0udzydObMDi65C59-oq54B9ZmjSZ1wVH3h+v4XiVm6QDA@mail.gmail.com
at least have it as a separate patch as part of this set.

I will continue reviewing the patch, but i feel this may be close to
be marked RFC, although
not sure if it will get a committer review before code freeze.

[0]: /messages/by-id/CAA5RZ0udzydObMDi65C59-oq54B9ZmjSZ1wVH3h+v4XiVm6QDA@mail.gmail.com

--
Sami Imseih
Amazon Web Services (AWS)

Attachments:

sami-v13-edits.txttext/plain; charset=US-ASCII; name=sami-v13-edits.txtDownload
From c8886d5ac14f31897a7f8058a1caab3d9213993e Mon Sep 17 00:00:00 2001
From: Sami Imseih <simseih@amazon.com>
Date: Tue, 1 Apr 2025 12:27:23 -0500
Subject: [PATCH 1/1] Introduce the ability to enable/disable indexes using
 ALTER INDEX

---
 doc/src/sgml/catalogs.sgml                 |  11 +
 doc/src/sgml/ref/alter_index.sgml          |  43 ++
 doc/src/sgml/ref/create_index.sgml         |  29 ++
 src/backend/bootstrap/bootparse.y          |   2 +
 src/backend/catalog/index.c                |  31 +-
 src/backend/catalog/toasting.c             |   2 +-
 src/backend/commands/indexcmds.c           |   4 +
 src/backend/commands/tablecmds.c           |  66 +++
 src/backend/optimizer/util/plancat.c       |  14 +
 src/backend/parser/gram.y                  |  48 +-
 src/backend/parser/parse_utilcmd.c         |   3 +
 src/backend/utils/adt/ruleutils.c          |   4 +
 src/backend/utils/cache/relcache.c         |   1 +
 src/include/catalog/index.h                |   1 +
 src/include/catalog/pg_index.h             |   1 +
 src/include/nodes/parsenodes.h             |   3 +
 src/include/nodes/pathnodes.h              |   2 +
 src/test/regress/expected/create_index.out | 505 +++++++++++++++++++++
 src/test/regress/sql/create_index.sql      | 192 ++++++++
 19 files changed, 954 insertions(+), 8 deletions(-)

diff --git a/doc/src/sgml/catalogs.sgml b/doc/src/sgml/catalogs.sgml
index fb050635551..123fcb04892 100644
--- a/doc/src/sgml/catalogs.sgml
+++ b/doc/src/sgml/catalogs.sgml
@@ -4618,6 +4618,17 @@ SCRAM-SHA-256$<replaceable>&lt;iteration count&gt;</replaceable>:<replaceable>&l
        partial index.
       </para></entry>
      </row>
+
+     <row>
+      <entry role="catalog_table_entry"><para role="column_definition">
+       <structfield>indisenabled</structfield> <type>bool</type>
+      </para>
+      <para>
+       If true, the index is currently enabled and should be used for queries.
+       If false, the index is disabled and should not be used for queries,
+       but is still maintained when the table is modified. Default is true.
+      </para></entry>
+     </row>
     </tbody>
    </tgroup>
   </table>
diff --git a/doc/src/sgml/ref/alter_index.sgml b/doc/src/sgml/ref/alter_index.sgml
index 1d42d05d858..04b3b0b9bfe 100644
--- a/doc/src/sgml/ref/alter_index.sgml
+++ b/doc/src/sgml/ref/alter_index.sgml
@@ -31,6 +31,8 @@ ALTER INDEX [ IF EXISTS ] <replaceable class="parameter">name</replaceable> ALTE
     SET STATISTICS <replaceable class="parameter">integer</replaceable>
 ALTER INDEX ALL IN TABLESPACE <replaceable class="parameter">name</replaceable> [ OWNED BY <replaceable class="parameter">role_name</replaceable> [, ... ] ]
     SET TABLESPACE <replaceable class="parameter">new_tablespace</replaceable> [ NOWAIT ]
+ALTER INDEX [ IF EXISTS ] <replaceable class="parameter">name</replaceable> ENABLE
+ALTER INDEX [ IF EXISTS ] <replaceable class="parameter">name</replaceable> DISABLE
 </synopsis>
  </refsynopsisdiv>
 
@@ -159,6 +161,33 @@ ALTER INDEX ALL IN TABLESPACE <replaceable class="parameter">name</replaceable>
     </listitem>
    </varlistentry>
 
+   <varlistentry>
+    <term><literal>ENABLE</literal></term>
+    <listitem>
+     <para>
+      Enable the specified index. The index will be used by the query planner
+      for query optimization. This is the default state for newly created indexes.
+     </para>
+    </listitem>
+   </varlistentry>
+
+   <varlistentry>
+    <term><literal>DISABLE</literal></term>
+    <listitem>
+     <para>
+      Disable the specified index. A disabled index is not used by the query planner
+      for query optimization, but it is still maintained when the underlying table
+      data changes. This can be useful for testing query performance with and without
+      specific indexes, temporarily reducing the overhead of index maintenance
+      during bulk data loading operations, or verifying an index is not being used
+      before dropping it. If performance degrades after disabling an index, it can be
+      easily re-enabled. Before disabling, it's recommended to check
+      <structname>pg_stat_user_indexes</structname>.<structfield>idx_scan</structfield>
+      to identify potentially unused indexes.
+     </para>
+    </listitem>
+   </varlistentry>
+
   </variablelist>
   </para>
 
@@ -301,6 +330,20 @@ CREATE INDEX coord_idx ON measured (x, y, (z + t));
 ALTER INDEX coord_idx ALTER COLUMN 3 SET STATISTICS 1000;
 </programlisting></para>
 
+  <para>
+   To enable an index:
+<programlisting>
+ALTER INDEX idx_name ENABLE;
+</programlisting>
+  </para>
+
+  <para>
+   To disable an index:
+<programlisting>
+ALTER INDEX idx_name DISABLE;
+</programlisting>
+  </para>
+
  </refsect1>
 
  <refsect1>
diff --git a/doc/src/sgml/ref/create_index.sgml b/doc/src/sgml/ref/create_index.sgml
index 208389e8006..d7a2f7df852 100644
--- a/doc/src/sgml/ref/create_index.sgml
+++ b/doc/src/sgml/ref/create_index.sgml
@@ -28,6 +28,7 @@ CREATE [ UNIQUE ] INDEX [ CONCURRENTLY ] [ [ IF NOT EXISTS ] <replaceable class=
     [ WITH ( <replaceable class="parameter">storage_parameter</replaceable> [= <replaceable class="parameter">value</replaceable>] [, ... ] ) ]
     [ TABLESPACE <replaceable class="parameter">tablespace_name</replaceable> ]
     [ WHERE <replaceable class="parameter">predicate</replaceable> ]
+    [ DISABLE ]
 </synopsis>
  </refsynopsisdiv>
 
@@ -380,6 +381,19 @@ CREATE [ UNIQUE ] INDEX [ CONCURRENTLY ] [ [ IF NOT EXISTS ] <replaceable class=
       </listitem>
      </varlistentry>
 
+    <varlistentry>
+      <term><literal>DISABLE</literal></term>
+      <listitem>
+       <para>
+        Creates the index in a disabled state (default enabled). A disabled index
+        is not used by the query planner for query optimization, but it is still
+        maintained when the underlying table data changes. This can be useful when
+        you want to create an index without immediately impacting query performance,
+        allowing you to enable it later at a more convenient time. The index can be
+        enabled later using <command>ALTER INDEX ... ENABLE</command>.
+       </para>
+      </listitem>
+     </varlistentry>
     </variablelist>
 
   <refsect2 id="sql-createindex-storage-parameters" xreflabel="Index Storage Parameters">
@@ -701,6 +715,14 @@ Indexes:
     partitioned index is a metadata only operation.
    </para>
 
+   <para>
+    When creating an index with the <literal>DISABLE</literal> option, the index
+    is created but not used for query planning. This can be useful for preparing
+    an index in advance of its use or for testing purposes. The index will still
+    be maintained as the table is modified, allowing it to be enabled later without
+    needing to be rebuilt. By default, all new indexes are enabled.
+   </para>
+
   </refsect2>
  </refsect1>
 
@@ -980,6 +1002,13 @@ SELECT * FROM points
 CREATE INDEX CONCURRENTLY sales_quantity_index ON sales_table (quantity);
 </programlisting></para>
 
+  <para>
+   To create an index on the table <literal>test_table</literal> with the default
+   name, but have it initially disabled:
+<programlisting>
+CREATE INDEX ON test_table (col1) DISABLE;
+</programlisting>
+  </para>
  </refsect1>
 
  <refsect1>
diff --git a/src/backend/bootstrap/bootparse.y b/src/backend/bootstrap/bootparse.y
index 9833f52c1be..9eea080ab5b 100644
--- a/src/backend/bootstrap/bootparse.y
+++ b/src/backend/bootstrap/bootparse.y
@@ -303,6 +303,7 @@ Boot_DeclareIndexStmt:
 					stmt->concurrent = false;
 					stmt->if_not_exists = false;
 					stmt->reset_default_tblspc = false;
+					stmt->isenabled = true;
 
 					/* locks and races need not concern us in bootstrap mode */
 					relationId = RangeVarGetRelid(stmt->relation, NoLock,
@@ -356,6 +357,7 @@ Boot_DeclareUniqueIndexStmt:
 					stmt->concurrent = false;
 					stmt->if_not_exists = false;
 					stmt->reset_default_tblspc = false;
+					stmt->isenabled = true;
 
 					/* locks and races need not concern us in bootstrap mode */
 					relationId = RangeVarGetRelid(stmt->relation, NoLock,
diff --git a/src/backend/catalog/index.c b/src/backend/catalog/index.c
index 739a92bdcc1..510755a4c0b 100644
--- a/src/backend/catalog/index.c
+++ b/src/backend/catalog/index.c
@@ -119,7 +119,8 @@ static void UpdateIndexRelation(Oid indexoid, Oid heapoid,
 								bool isexclusion,
 								bool immediate,
 								bool isvalid,
-								bool isready);
+								bool isready,
+								bool isenabled);
 static void index_update_stats(Relation rel,
 							   bool hasindex,
 							   double reltuples);
@@ -571,7 +572,8 @@ UpdateIndexRelation(Oid indexoid,
 					bool isexclusion,
 					bool immediate,
 					bool isvalid,
-					bool isready)
+					bool isready,
+					bool isenabled)
 {
 	int2vector *indkey;
 	oidvector  *indcollation;
@@ -649,6 +651,7 @@ UpdateIndexRelation(Oid indexoid,
 	values[Anum_pg_index_indisready - 1] = BoolGetDatum(isready);
 	values[Anum_pg_index_indislive - 1] = BoolGetDatum(true);
 	values[Anum_pg_index_indisreplident - 1] = BoolGetDatum(false);
+	values[Anum_pg_index_indisenabled - 1] = BoolGetDatum(isenabled);
 	values[Anum_pg_index_indkey - 1] = PointerGetDatum(indkey);
 	values[Anum_pg_index_indcollation - 1] = PointerGetDatum(indcollation);
 	values[Anum_pg_index_indclass - 1] = PointerGetDatum(indclass);
@@ -714,6 +717,8 @@ UpdateIndexRelation(Oid indexoid,
  *			already exists.
  *		INDEX_CREATE_PARTITIONED:
  *			create a partitioned index (table must be partitioned)
+ *		INDEX_CREATE_DISABLED:
+*				create the index as disabled if instructed, defaults to being enabled.
  * constr_flags: flags passed to index_constraint_create
  *		(only if INDEX_CREATE_ADD_CONSTRAINT is set)
  * allow_system_table_mods: allow table to be a system catalog
@@ -759,6 +764,7 @@ index_create(Relation heapRelation,
 	bool		invalid = (flags & INDEX_CREATE_INVALID) != 0;
 	bool		concurrent = (flags & INDEX_CREATE_CONCURRENT) != 0;
 	bool		partitioned = (flags & INDEX_CREATE_PARTITIONED) != 0;
+	bool		isenabled = (flags & INDEX_CREATE_ENABLED) != 0;
 	char		relkind;
 	TransactionId relfrozenxid;
 	MultiXactId relminmxid;
@@ -1042,13 +1048,15 @@ index_create(Relation heapRelation,
 	 *	  (Or, could define a rule to maintain the predicate) --Nels, Feb '92
 	 * ----------------
 	 */
+
 	UpdateIndexRelation(indexRelationId, heapRelationId, parentIndexRelid,
 						indexInfo,
 						collationIds, opclassIds, coloptions,
 						isprimary, is_exclusion,
 						(constr_flags & INDEX_CONSTR_CREATE_DEFERRABLE) == 0,
 						!concurrent && !invalid,
-						!concurrent);
+						!concurrent,
+						isenabled);
 
 	/*
 	 * Register relcache invalidation on the indexes' heap relation, to
@@ -1317,6 +1325,8 @@ index_concurrently_create_copy(Relation heapRelation, Oid oldIndexId,
 	List	   *indexColNames = NIL;
 	List	   *indexExprs = NIL;
 	List	   *indexPreds = NIL;
+	Form_pg_index indexForm;
+	bits16		createFlags;
 
 	indexRelation = index_open(oldIndexId, RowExclusiveLock);
 
@@ -1344,6 +1354,9 @@ index_concurrently_create_copy(Relation heapRelation, Oid oldIndexId,
 											Anum_pg_index_indoption);
 	indcoloptions = (int2vector *) DatumGetPointer(colOptionDatum);
 
+	/* Get the enabled state of the original index */
+	indexForm = (Form_pg_index) GETSTRUCT(indexTuple);
+
 	/* Fetch reloptions of index if any */
 	classTuple = SearchSysCache1(RELOID, ObjectIdGetDatum(oldIndexId));
 	if (!HeapTupleIsValid(classTuple))
@@ -1435,6 +1448,16 @@ index_concurrently_create_copy(Relation heapRelation, Oid oldIndexId,
 		stattargets[i].isnull = isnull;
 	}
 
+	/*
+	 * Determine the create flags for the new index. We always use SKIP_BUILD
+	 * and CONCURRENT for concurrent reindexing. If the original index was
+	 * enabled, we also set the ENABLED flag to maintain the same state in the
+	 * new index.
+	 */
+	createFlags = INDEX_CREATE_SKIP_BUILD | INDEX_CREATE_CONCURRENT;
+	if (indexForm->indisenabled)
+		createFlags |= INDEX_CREATE_ENABLED;
+
 	/*
 	 * Now create the new index.
 	 *
@@ -1458,7 +1481,7 @@ index_concurrently_create_copy(Relation heapRelation, Oid oldIndexId,
 							  indcoloptions->values,
 							  stattargets,
 							  reloptionsDatum,
-							  INDEX_CREATE_SKIP_BUILD | INDEX_CREATE_CONCURRENT,
+							  createFlags,
 							  0,
 							  true, /* allow table to be a system catalog? */
 							  false,	/* is_internal? */
diff --git a/src/backend/catalog/toasting.c b/src/backend/catalog/toasting.c
index 874a8fc89ad..a612a0a3de1 100644
--- a/src/backend/catalog/toasting.c
+++ b/src/backend/catalog/toasting.c
@@ -325,7 +325,7 @@ create_toast_table(Relation rel, Oid toastOid, Oid toastIndexOid,
 				 BTREE_AM_OID,
 				 rel->rd_rel->reltablespace,
 				 collationIds, opclassIds, NULL, coloptions, NULL, (Datum) 0,
-				 INDEX_CREATE_IS_PRIMARY, 0, true, true, NULL);
+				 INDEX_CREATE_IS_PRIMARY | INDEX_CREATE_ENABLED, 0, true, true, NULL);
 
 	table_close(toast_rel, NoLock);
 
diff --git a/src/backend/commands/indexcmds.c b/src/backend/commands/indexcmds.c
index 33c2106c17c..90f9b111e57 100644
--- a/src/backend/commands/indexcmds.c
+++ b/src/backend/commands/indexcmds.c
@@ -1222,6 +1222,10 @@ DefineIndex(Oid tableId,
 		flags |= INDEX_CREATE_PARTITIONED;
 	if (stmt->primary)
 		flags |= INDEX_CREATE_IS_PRIMARY;
+	if (stmt->isenabled)
+		flags |= INDEX_CREATE_ENABLED;
+	else
+		flags &= ~INDEX_CREATE_ENABLED;
 
 	/*
 	 * If the table is partitioned, and recursion was declined but partitions
diff --git a/src/backend/commands/tablecmds.c b/src/backend/commands/tablecmds.c
index 10624353b0a..58d3d29d565 100644
--- a/src/backend/commands/tablecmds.c
+++ b/src/backend/commands/tablecmds.c
@@ -719,6 +719,7 @@ static List *GetParentedForeignKeyRefs(Relation partition);
 static void ATDetachCheckNoForeignKeyRefs(Relation partition);
 static char GetAttributeCompression(Oid atttypid, const char *compression);
 static char GetAttributeStorage(Oid atttypid, const char *storagemode);
+static void ATExecEnableDisableIndex(Relation rel, bool enable);
 
 
 /* ----------------------------------------------------------------
@@ -4685,6 +4686,8 @@ AlterTableGetLockLevel(List *cmds)
 			case AT_SetExpression:
 			case AT_DropExpression:
 			case AT_SetCompression:
+			case AT_EnableIndex:
+			case AT_DisableIndex:
 				cmd_lockmode = AccessExclusiveLock;
 				break;
 
@@ -5249,6 +5252,12 @@ ATPrepCmd(List **wqueue, Relation rel, AlterTableCmd *cmd,
 			/* No command-specific prep needed */
 			pass = AT_PASS_MISC;
 			break;
+		case AT_EnableIndex:
+		case AT_DisableIndex:
+			ATSimplePermissions(cmd->subtype, rel, ATT_INDEX | ATT_PARTITIONED_INDEX);
+			/* No command-specific prep needed */
+			pass = AT_PASS_MISC;
+			break;
 		default:				/* oops */
 			elog(ERROR, "unrecognized alter table type: %d",
 				 (int) cmd->subtype);
@@ -5645,6 +5654,12 @@ ATExecCmd(List **wqueue, AlteredTableInfo *tab,
 		case AT_DetachPartitionFinalize:
 			address = ATExecDetachPartitionFinalize(rel, ((PartitionCmd *) cmd->def)->name);
 			break;
+		case AT_EnableIndex:
+			ATExecEnableDisableIndex(rel, true);
+			break;
+		case AT_DisableIndex:
+			ATExecEnableDisableIndex(rel, false);
+			break;
 		default:				/* oops */
 			elog(ERROR, "unrecognized alter table type: %d",
 				 (int) cmd->subtype);
@@ -6591,6 +6606,8 @@ alter_table_type_to_string(AlterTableType cmdtype)
 			return "DROP COLUMN";
 		case AT_AddIndex:
 		case AT_ReAddIndex:
+		case AT_EnableIndex:
+		case AT_DisableIndex:
 			return NULL;		/* not real grammar */
 		case AT_AddConstraint:
 		case AT_ReAddConstraint:
@@ -21466,3 +21483,52 @@ GetAttributeStorage(Oid atttypid, const char *storagemode)
 
 	return cstorage;
 }
+
+/*
+ * ATExecEnableDisableIndex
+ * Performs a catalog update to enable or disable an index in pg_index.
+ */
+static void
+ATExecEnableDisableIndex(Relation rel, bool enable)
+{
+	Oid			indexOid = RelationGetRelid(rel);
+	Relation	pg_index;
+	HeapTuple	indexTuple;
+	Form_pg_index indexForm;
+	bool		updated = false;
+
+	pg_index = table_open(IndexRelationId, RowExclusiveLock);
+
+	indexTuple = SearchSysCacheCopy1(INDEXRELID, ObjectIdGetDatum(indexOid));
+	if (!HeapTupleIsValid(indexTuple))
+		elog(ERROR, "could not find tuple for index %u", indexOid);
+
+	indexForm = (Form_pg_index) GETSTRUCT(indexTuple);
+	if (indexForm->indcheckxmin)
+	{
+		heap_freetuple(indexTuple);
+		table_close(pg_index, RowExclusiveLock);
+		ereport(ERROR,
+				(errcode(ERRCODE_OBJECT_NOT_IN_PREREQUISITE_STATE),
+				 errmsg("cannot enable/disable index while indcheckxmin is true"),
+				 errhint("Wait for all transactions that might see inconsistent HOT chains to complete")));
+	}
+
+	if (indexForm->indisenabled != enable)
+	{
+		indexForm->indisenabled = enable;
+
+		CatalogTupleUpdate(pg_index, &indexTuple->t_self, indexTuple);
+		updated = true;
+	}
+
+	heap_freetuple(indexTuple);
+	table_close(pg_index, RowExclusiveLock);
+
+	if (updated)
+	{
+		CacheInvalidateRelcache(rel);
+		InvokeObjectPostAlterHook(IndexRelationId, indexOid, 0);
+		CommandCounterIncrement();
+	}
+}
diff --git a/src/backend/optimizer/util/plancat.c b/src/backend/optimizer/util/plancat.c
index 0489ad36644..08167df3f8b 100644
--- a/src/backend/optimizer/util/plancat.c
+++ b/src/backend/optimizer/util/plancat.c
@@ -295,6 +295,20 @@ get_relation_info(PlannerInfo *root, Oid relationObjectId, bool inhparent,
 			info->opcintype = (Oid *) palloc(sizeof(Oid) * nkeycolumns);
 			info->canreturn = (bool *) palloc(sizeof(bool) * ncolumns);
 
+			/*
+			 * Skip disabled indexes altogether, as they should not be
+			 * considered for query planning. This builds the data structure
+			 * for the planner's use and we make it part of IndexOptInfo since
+			 * the index is already open. We also close the relation before
+			 * continuing to the next index.
+			 */
+			info->enabled = index->indisenabled;
+			if (!info->enabled)
+			{
+				index_close(indexRelation, NoLock);
+				continue;
+			}
+
 			for (i = 0; i < ncolumns; i++)
 			{
 				info->indexkeys[i] = index->indkey.values[i];
diff --git a/src/backend/parser/gram.y b/src/backend/parser/gram.y
index 0fc502a3a40..414a830ba1f 100644
--- a/src/backend/parser/gram.y
+++ b/src/backend/parser/gram.y
@@ -324,7 +324,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 %type <ival>	add_drop opt_asc_desc opt_nulls_order
 
 %type <node>	alter_table_cmd alter_type_cmd opt_collate_clause
-	   replica_identity partition_cmd index_partition_cmd
+	   replica_identity partition_cmd index_partition_cmd index_alter_cmd
 %type <list>	alter_table_cmds alter_type_cmds
 %type <list>    alter_identity_column_option_list
 %type <defelt>  alter_identity_column_option
@@ -491,6 +491,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 %type <boolean> opt_unique opt_verbose opt_full
 %type <boolean> opt_freeze opt_analyze opt_default
 %type <defelt>	opt_binary copy_delimiter
+%type <boolean>  opt_index_enabled
 
 %type <boolean> copy_from opt_program
 
@@ -2157,6 +2158,24 @@ AlterTableStmt:
 					n->nowait = $13;
 					$$ = (Node *) n;
 				}
+		| ALTER INDEX qualified_name index_alter_cmd
+				{
+					AlterTableStmt *n = makeNode(AlterTableStmt);
+					n->relation = $3;
+					n->cmds = list_make1($4);
+					n->objtype = OBJECT_INDEX;
+					n->missing_ok = false;
+					$$ = (Node *) n;
+				}
+		| ALTER INDEX IF_P EXISTS qualified_name index_alter_cmd
+				{
+					AlterTableStmt *n = makeNode(AlterTableStmt);
+					n->relation = $5;
+					n->cmds = list_make1($6);
+					n->objtype = OBJECT_INDEX;
+					n->missing_ok = true;
+					$$ = (Node *) n;
+				}
 		|	ALTER INDEX qualified_name alter_table_cmds
 				{
 					AlterTableStmt *n = makeNode(AlterTableStmt);
@@ -2382,6 +2401,21 @@ index_partition_cmd:
 				}
 		;
 
+index_alter_cmd:
+		/* ALTER INDEX <name> ENABLE|DISABLE */
+		ENABLE_P
+			{
+				AlterTableCmd *n = makeNode(AlterTableCmd);
+				n->subtype = AT_EnableIndex;
+				$$ = (Node *) n;
+			}
+		| DISABLE_P
+			{
+				AlterTableCmd *n = makeNode(AlterTableCmd);
+				n->subtype = AT_DisableIndex;
+				$$ = (Node *) n;
+			}
+		;
 alter_table_cmd:
 			/* ALTER TABLE <name> ADD <coldef> */
 			ADD_P columnDef
@@ -8185,7 +8219,7 @@ defacl_privilege_target:
 
 IndexStmt:	CREATE opt_unique INDEX opt_concurrently opt_single_name
 			ON relation_expr access_method_clause '(' index_params ')'
-			opt_include opt_unique_null_treatment opt_reloptions OptTableSpace where_clause
+			opt_include opt_unique_null_treatment opt_reloptions OptTableSpace where_clause opt_index_enabled
 				{
 					IndexStmt *n = makeNode(IndexStmt);
 
@@ -8200,6 +8234,7 @@ IndexStmt:	CREATE opt_unique INDEX opt_concurrently opt_single_name
 					n->options = $14;
 					n->tableSpace = $15;
 					n->whereClause = $16;
+					n->isenabled = $17;
 					n->excludeOpNames = NIL;
 					n->idxcomment = NULL;
 					n->indexOid = InvalidOid;
@@ -8217,7 +8252,7 @@ IndexStmt:	CREATE opt_unique INDEX opt_concurrently opt_single_name
 				}
 			| CREATE opt_unique INDEX opt_concurrently IF_P NOT EXISTS name
 			ON relation_expr access_method_clause '(' index_params ')'
-			opt_include opt_unique_null_treatment opt_reloptions OptTableSpace where_clause
+			opt_include opt_unique_null_treatment opt_reloptions OptTableSpace where_clause opt_index_enabled
 				{
 					IndexStmt *n = makeNode(IndexStmt);
 
@@ -8232,6 +8267,7 @@ IndexStmt:	CREATE opt_unique INDEX opt_concurrently opt_single_name
 					n->options = $17;
 					n->tableSpace = $18;
 					n->whereClause = $19;
+					n->isenabled = $20;
 					n->excludeOpNames = NIL;
 					n->idxcomment = NULL;
 					n->indexOid = InvalidOid;
@@ -8254,6 +8290,12 @@ opt_unique:
 			| /*EMPTY*/								{ $$ = false; }
 		;
 
+opt_index_enabled:
+			ENABLE_P                      { $$ = true; }
+			| DISABLE_P                   { $$ = false; }
+			| /*EMPTY*/                 	{ $$ = true; }
+		;
+
 access_method_clause:
 			USING name								{ $$ = $2; }
 			| /*EMPTY*/								{ $$ = DEFAULT_INDEX_TYPE; }
diff --git a/src/backend/parser/parse_utilcmd.c b/src/backend/parser/parse_utilcmd.c
index 9c1541e1fea..488de757bc2 100644
--- a/src/backend/parser/parse_utilcmd.c
+++ b/src/backend/parser/parse_utilcmd.c
@@ -1745,6 +1745,7 @@ generateClonedIndexStmt(RangeVar *heapRel, Relation source_idx,
 	index->concurrent = false;
 	index->if_not_exists = false;
 	index->reset_default_tblspc = false;
+	index->isenabled = idxrec->indisenabled;
 
 	/*
 	 * We don't try to preserve the name of the source index; instead, just
@@ -2366,6 +2367,8 @@ transformIndexConstraint(Constraint *constraint, CreateStmtContext *cxt)
 	index->concurrent = false;
 	index->if_not_exists = false;
 	index->reset_default_tblspc = constraint->reset_default_tblspc;
+	/* Ensure indexes for constraints are created as enabled by default */
+	index->isenabled = true;
 
 	/*
 	 * If it's ALTER TABLE ADD CONSTRAINT USING INDEX, look up the index and
diff --git a/src/backend/utils/adt/ruleutils.c b/src/backend/utils/adt/ruleutils.c
index 9e90acedb91..3f6a89efaf4 100644
--- a/src/backend/utils/adt/ruleutils.c
+++ b/src/backend/utils/adt/ruleutils.c
@@ -1565,6 +1565,10 @@ pg_get_indexdef_worker(Oid indexrelid, int colno,
 			else
 				appendStringInfo(&buf, " WHERE %s", str);
 		}
+
+		/* Add DISABLE clause if the index is disabled */
+		if (!idxrec->indisenabled)
+			appendStringInfoString(&buf, " DISABLE");
 	}
 
 	/* Clean up */
diff --git a/src/backend/utils/cache/relcache.c b/src/backend/utils/cache/relcache.c
index 9f54a9e72b7..5e59a73d655 100644
--- a/src/backend/utils/cache/relcache.c
+++ b/src/backend/utils/cache/relcache.c
@@ -2318,6 +2318,7 @@ RelationReloadIndexInfo(Relation relation)
 		relation->rd_index->indisready = index->indisready;
 		relation->rd_index->indislive = index->indislive;
 		relation->rd_index->indisreplident = index->indisreplident;
+		relation->rd_index->indisenabled = index->indisenabled;
 
 		/* Copy xmin too, as that is needed to make sense of indcheckxmin */
 		HeapTupleHeaderSetXmin(relation->rd_indextuple->t_data,
diff --git a/src/include/catalog/index.h b/src/include/catalog/index.h
index 4daa8bef5ee..a390ab76789 100644
--- a/src/include/catalog/index.h
+++ b/src/include/catalog/index.h
@@ -65,6 +65,7 @@ extern void index_check_primary_key(Relation heapRel,
 #define	INDEX_CREATE_IF_NOT_EXISTS			(1 << 4)
 #define	INDEX_CREATE_PARTITIONED			(1 << 5)
 #define INDEX_CREATE_INVALID				(1 << 6)
+#define INDEX_CREATE_ENABLED        (1 << 7)
 
 extern Oid	index_create(Relation heapRelation,
 						 const char *indexRelationName,
diff --git a/src/include/catalog/pg_index.h b/src/include/catalog/pg_index.h
index 4392b9d221d..766a52193cb 100644
--- a/src/include/catalog/pg_index.h
+++ b/src/include/catalog/pg_index.h
@@ -44,6 +44,7 @@ CATALOG(pg_index,2610,IndexRelationId) BKI_SCHEMA_MACRO
 	bool		indisready;		/* is this index ready for inserts? */
 	bool		indislive;		/* is this index alive at all? */
 	bool		indisreplident; /* is this index the identity for replication? */
+	bool		indisenabled;	/* is this index enabled for use by queries? */
 
 	/* variable-length fields start here, but we allow direct access to indkey */
 	int2vector	indkey BKI_FORCE_NOT_NULL;	/* column numbers of indexed cols,
diff --git a/src/include/nodes/parsenodes.h b/src/include/nodes/parsenodes.h
index df331b1c0d9..aeb9ac844a1 100644
--- a/src/include/nodes/parsenodes.h
+++ b/src/include/nodes/parsenodes.h
@@ -2472,6 +2472,8 @@ typedef enum AlterTableType
 	AT_SetIdentity,				/* SET identity column options */
 	AT_DropIdentity,			/* DROP IDENTITY */
 	AT_ReAddStatistics,			/* internal to commands/tablecmds.c */
+	AT_EnableIndex,				/* ENABLE INDEX */
+	AT_DisableIndex,			/* DISABLE INDEX */
 } AlterTableType;
 
 typedef struct AlterTableCmd	/* one subcommand of an ALTER TABLE */
@@ -3468,6 +3470,7 @@ typedef struct IndexStmt
 	bool		if_not_exists;	/* just do nothing if index already exists? */
 	bool		reset_default_tblspc;	/* reset default_tablespace prior to
 										 * executing */
+	bool		isenabled;		/* true if ENABLE (default), false if DISABLE */
 } IndexStmt;
 
 /* ----------------------
diff --git a/src/include/nodes/pathnodes.h b/src/include/nodes/pathnodes.h
index c24a1fc8514..a9833fe2a64 100644
--- a/src/include/nodes/pathnodes.h
+++ b/src/include/nodes/pathnodes.h
@@ -1239,6 +1239,8 @@ struct IndexOptInfo
 	/* AM's cost estimator */
 	/* Rather than include amapi.h here, we declare amcostestimate like this */
 	void		(*amcostestimate) (struct PlannerInfo *, struct IndexPath *, double, Cost *, Cost *, Selectivity *, double *, double *) pg_node_attr(read_write_ignore);
+	/* true if this index is enabled */
+	bool		enabled;
 };
 
 /*
diff --git a/src/test/regress/expected/create_index.out b/src/test/regress/expected/create_index.out
index 15be0043ad4..84461f234b4 100644
--- a/src/test/regress/expected/create_index.out
+++ b/src/test/regress/expected/create_index.out
@@ -3394,6 +3394,511 @@ ERROR:  REINDEX SCHEMA cannot run inside a transaction block
 END;
 -- concurrently
 REINDEX SCHEMA CONCURRENTLY schema_to_reindex;
+-- Test enable/disable functionality for indexes
+CREATE TABLE index_test(
+    id INT PRIMARY KEY,
+    data TEXT,
+    num INT,
+    vector INT[],
+    range INT4RANGE
+);
+INSERT INTO index_test
+SELECT
+    g,
+    'data ' || g,
+    g % 100,
+    ARRAY[g, g+1, g+2],
+    int4range(g, g+10)
+FROM generate_series(1, 1000) g;
+-- Function for testing
+CREATE FUNCTION get_data_length(text) RETURNS INT AS $$
+    SELECT length($1);
+$$ LANGUAGE SQL IMMUTABLE;
+-- Helper function to show index status
+CREATE OR REPLACE FUNCTION show_index_status(index_name text)
+RETURNS TABLE (
+    indexrelid regclass,
+    indisvalid boolean,
+    indisready boolean,
+    indislive boolean,
+    indisenabled boolean
+) AS $$
+BEGIN
+    RETURN QUERY EXECUTE format('
+        SELECT indexrelid::regclass, indisvalid, indisready, indislive, indisenabled
+        FROM pg_index
+        WHERE indexrelid = %L::regclass', index_name);
+END;
+$$ LANGUAGE plpgsql;
+-- Create and test each index type
+-- 1. Basic single-column index
+CREATE INDEX idx_single ON index_test(data);
+SELECT show_index_status('idx_single');
+  show_index_status   
+----------------------
+ (idx_single,t,t,t,t)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE data = 'data 500';
+                  QUERY PLAN                   
+-----------------------------------------------
+ Bitmap Heap Scan on index_test
+   Recheck Cond: (data = 'data 500'::text)
+   ->  Bitmap Index Scan on idx_single
+         Index Cond: (data = 'data 500'::text)
+(4 rows)
+
+ALTER INDEX idx_single DISABLE;
+SELECT show_index_status('idx_single');
+  show_index_status   
+----------------------
+ (idx_single,t,t,t,f)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE data = 'data 500';
+             QUERY PLAN              
+-------------------------------------
+ Seq Scan on index_test
+   Filter: (data = 'data 500'::text)
+(2 rows)
+
+ALTER INDEX idx_single ENABLE;
+SELECT show_index_status('idx_single');
+  show_index_status   
+----------------------
+ (idx_single,t,t,t,t)
+(1 row)
+
+-- 2. Multi-column index
+CREATE INDEX idx_multi ON index_test(num, data);
+SELECT show_index_status('idx_multi');
+  show_index_status  
+---------------------
+ (idx_multi,t,t,t,t)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE num = 50 AND data > 'data 500';
+                           QUERY PLAN                           
+----------------------------------------------------------------
+ Bitmap Heap Scan on index_test
+   Recheck Cond: ((num = 50) AND (data > 'data 500'::text))
+   ->  Bitmap Index Scan on idx_multi
+         Index Cond: ((num = 50) AND (data > 'data 500'::text))
+(4 rows)
+
+ALTER INDEX idx_multi DISABLE;
+SELECT show_index_status('idx_multi');
+  show_index_status  
+---------------------
+ (idx_multi,t,t,t,f)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE num = 50 AND data > 'data 500';
+                      QUERY PLAN                      
+------------------------------------------------------
+ Seq Scan on index_test
+   Filter: ((data > 'data 500'::text) AND (num = 50))
+(2 rows)
+
+ALTER INDEX idx_multi ENABLE;
+SELECT show_index_status('idx_multi');
+  show_index_status  
+---------------------
+ (idx_multi,t,t,t,t)
+(1 row)
+
+-- 3. Partial index
+CREATE INDEX idx_partial ON index_test(num) WHERE num < 50;
+SELECT show_index_status('idx_partial');
+   show_index_status   
+-----------------------
+ (idx_partial,t,t,t,t)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE num = 25;
+               QUERY PLAN               
+----------------------------------------
+ Bitmap Heap Scan on index_test
+   Recheck Cond: (num = 25)
+   ->  Bitmap Index Scan on idx_partial
+         Index Cond: (num = 25)
+(4 rows)
+
+ALTER INDEX idx_partial DISABLE;
+SELECT show_index_status('idx_partial');
+   show_index_status   
+-----------------------
+ (idx_partial,t,t,t,f)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE num = 25;
+              QUERY PLAN              
+--------------------------------------
+ Bitmap Heap Scan on index_test
+   Recheck Cond: (num = 25)
+   ->  Bitmap Index Scan on idx_multi
+         Index Cond: (num = 25)
+(4 rows)
+
+ALTER INDEX idx_partial ENABLE;
+SELECT show_index_status('idx_partial');
+   show_index_status   
+-----------------------
+ (idx_partial,t,t,t,t)
+(1 row)
+
+-- 4. Expression index
+CREATE INDEX idx_expression ON index_test((lower(data)));
+SELECT show_index_status('idx_expression');
+    show_index_status     
+--------------------------
+ (idx_expression,t,t,t,t)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE lower(data) = 'data 500';
+                      QUERY PLAN                      
+------------------------------------------------------
+ Bitmap Heap Scan on index_test
+   Recheck Cond: (lower(data) = 'data 500'::text)
+   ->  Bitmap Index Scan on idx_expression
+         Index Cond: (lower(data) = 'data 500'::text)
+(4 rows)
+
+ALTER INDEX idx_expression DISABLE;
+SELECT show_index_status('idx_expression');
+    show_index_status     
+--------------------------
+ (idx_expression,t,t,t,f)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE lower(data) = 'data 500';
+                 QUERY PLAN                 
+--------------------------------------------
+ Seq Scan on index_test
+   Filter: (lower(data) = 'data 500'::text)
+(2 rows)
+
+ALTER INDEX idx_expression ENABLE;
+SELECT show_index_status('idx_expression');
+    show_index_status     
+--------------------------
+ (idx_expression,t,t,t,t)
+(1 row)
+
+-- 5. GIN index
+CREATE INDEX idx_gin ON index_test USING gin(vector);
+SELECT show_index_status('idx_gin');
+ show_index_status 
+-------------------
+ (idx_gin,t,t,t,t)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE vector @> ARRAY[500];
+                     QUERY PLAN                     
+----------------------------------------------------
+ Bitmap Heap Scan on index_test
+   Recheck Cond: (vector @> '{500}'::integer[])
+   ->  Bitmap Index Scan on idx_gin
+         Index Cond: (vector @> '{500}'::integer[])
+(4 rows)
+
+ALTER INDEX idx_gin DISABLE;
+SELECT show_index_status('idx_gin');
+ show_index_status 
+-------------------
+ (idx_gin,t,t,t,f)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE vector @> ARRAY[500];
+                QUERY PLAN                
+------------------------------------------
+ Seq Scan on index_test
+   Filter: (vector @> '{500}'::integer[])
+(2 rows)
+
+ALTER INDEX idx_gin ENABLE;
+SELECT show_index_status('idx_gin');
+ show_index_status 
+-------------------
+ (idx_gin,t,t,t,t)
+(1 row)
+
+-- 6. GiST index
+CREATE INDEX idx_gist ON index_test USING gist(range);
+SELECT show_index_status('idx_gist');
+ show_index_status  
+--------------------
+ (idx_gist,t,t,t,t)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE range && int4range(100, 110);
+                      QUERY PLAN                       
+-------------------------------------------------------
+ Bitmap Heap Scan on index_test
+   Recheck Cond: (range && '[100,110)'::int4range)
+   ->  Bitmap Index Scan on idx_gist
+         Index Cond: (range && '[100,110)'::int4range)
+(4 rows)
+
+ALTER INDEX idx_gist DISABLE;
+SELECT show_index_status('idx_gist');
+ show_index_status  
+--------------------
+ (idx_gist,t,t,t,f)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE range && int4range(100, 110);
+                 QUERY PLAN                  
+---------------------------------------------
+ Seq Scan on index_test
+   Filter: (range && '[100,110)'::int4range)
+(2 rows)
+
+ALTER INDEX idx_gist ENABLE;
+SELECT show_index_status('idx_gist');
+ show_index_status  
+--------------------
+ (idx_gist,t,t,t,t)
+(1 row)
+
+-- 7. Covering index
+CREATE INDEX idx_covering ON index_test(num) INCLUDE (data);
+SELECT show_index_status('idx_covering');
+   show_index_status    
+------------------------
+ (idx_covering,t,t,t,t)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT num, data FROM index_test WHERE num = 50;
+               QUERY PLAN                
+-----------------------------------------
+ Bitmap Heap Scan on index_test
+   Recheck Cond: (num = 50)
+   ->  Bitmap Index Scan on idx_covering
+         Index Cond: (num = 50)
+(4 rows)
+
+ALTER INDEX idx_covering DISABLE;
+SELECT show_index_status('idx_covering');
+   show_index_status    
+------------------------
+ (idx_covering,t,t,t,f)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT num, data FROM index_test WHERE num = 50;
+              QUERY PLAN              
+--------------------------------------
+ Bitmap Heap Scan on index_test
+   Recheck Cond: (num = 50)
+   ->  Bitmap Index Scan on idx_multi
+         Index Cond: (num = 50)
+(4 rows)
+
+ALTER INDEX idx_covering ENABLE;
+SELECT show_index_status('idx_covering');
+   show_index_status    
+------------------------
+ (idx_covering,t,t,t,t)
+(1 row)
+
+-- 8. Unique index
+CREATE UNIQUE INDEX idx_unique ON index_test(id, data);
+SELECT show_index_status('idx_unique');
+  show_index_status   
+----------------------
+ (idx_unique,t,t,t,t)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE id = 500 AND data = 'data 500';
+                        QUERY PLAN                        
+----------------------------------------------------------
+ Index Scan using idx_unique on index_test
+   Index Cond: ((id = 500) AND (data = 'data 500'::text))
+(2 rows)
+
+ALTER INDEX idx_unique DISABLE;
+SELECT show_index_status('idx_unique');
+  show_index_status   
+----------------------
+ (idx_unique,t,t,t,f)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE id = 500 AND data = 'data 500';
+                   QUERY PLAN                   
+------------------------------------------------
+ Index Scan using index_test_pkey on index_test
+   Index Cond: (id = 500)
+   Filter: (data = 'data 500'::text)
+(3 rows)
+
+ALTER INDEX idx_unique ENABLE;
+SELECT show_index_status('idx_unique');
+  show_index_status   
+----------------------
+ (idx_unique,t,t,t,t)
+(1 row)
+
+-- 9. Function-based index
+CREATE INDEX idx_func ON index_test(get_data_length(data));
+SELECT show_index_status('idx_func');
+ show_index_status  
+--------------------
+ (idx_func,t,t,t,t)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE get_data_length(data) = 10;
+               QUERY PLAN                
+-----------------------------------------
+ Bitmap Heap Scan on index_test
+   Recheck Cond: (length(data) = 10)
+   ->  Bitmap Index Scan on idx_func
+         Index Cond: (length(data) = 10)
+(4 rows)
+
+ALTER INDEX idx_func DISABLE;
+SELECT show_index_status('idx_func');
+ show_index_status  
+--------------------
+ (idx_func,t,t,t,f)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE get_data_length(data) = 10;
+          QUERY PLAN           
+-------------------------------
+ Seq Scan on index_test
+   Filter: (length(data) = 10)
+(2 rows)
+
+ALTER INDEX idx_func ENABLE;
+SELECT show_index_status('idx_func');
+ show_index_status  
+--------------------
+ (idx_func,t,t,t,t)
+(1 row)
+
+-- 10. Join index
+CREATE TABLE join_test (id INT PRIMARY KEY, ref_id INT);
+INSERT INTO join_test SELECT g, g % 100 FROM generate_series(1, 1000) g;
+CREATE INDEX idx_join ON join_test(ref_id);
+SELECT show_index_status('idx_join');
+ show_index_status  
+--------------------
+ (idx_join,t,t,t,t)
+(1 row)
+
+EXPLAIN (COSTS OFF)
+SELECT jt.id, it.data
+FROM join_test jt
+JOIN index_test it ON jt.ref_id = it.num
+WHERE jt.id BETWEEN 100 AND 200;
+                          QUERY PLAN                           
+---------------------------------------------------------------
+ Hash Join
+   Hash Cond: (it.num = jt.ref_id)
+   ->  Seq Scan on index_test it
+   ->  Hash
+         ->  Bitmap Heap Scan on join_test jt
+               Recheck Cond: ((id >= 100) AND (id <= 200))
+               ->  Bitmap Index Scan on join_test_pkey
+                     Index Cond: ((id >= 100) AND (id <= 200))
+(8 rows)
+
+-- Disable all indexes to force seq scan
+ALTER INDEX idx_join DISABLE;
+ALTER INDEX join_test_pkey DISABLE;
+SELECT show_index_status('idx_join');
+ show_index_status  
+--------------------
+ (idx_join,t,t,t,f)
+(1 row)
+
+SELECT show_index_status('join_test_pkey');
+    show_index_status     
+--------------------------
+ (join_test_pkey,t,t,t,f)
+(1 row)
+
+EXPLAIN (COSTS OFF)
+SELECT jt.id, it.data
+FROM join_test jt
+JOIN index_test it ON jt.ref_id = it.num
+WHERE jt.id BETWEEN 100 AND 200;
+                     QUERY PLAN                      
+-----------------------------------------------------
+ Hash Join
+   Hash Cond: (it.num = jt.ref_id)
+   ->  Seq Scan on index_test it
+   ->  Hash
+         ->  Seq Scan on join_test jt
+               Filter: ((id >= 100) AND (id <= 200))
+(6 rows)
+
+ALTER INDEX idx_join ENABLE;
+ALTER INDEX join_test_pkey ENABLE;
+SELECT show_index_status('idx_join');
+ show_index_status  
+--------------------
+ (idx_join,t,t,t,t)
+(1 row)
+
+SELECT show_index_status('join_test_pkey');
+    show_index_status     
+--------------------------
+ (join_test_pkey,t,t,t,t)
+(1 row)
+
+-- Test REINDEX CONCURRENTLY
+REINDEX INDEX CONCURRENTLY idx_join;
+SELECT show_index_status('idx_join');
+ show_index_status  
+--------------------
+ (idx_join,t,t,t,t)
+(1 row)
+
+ALTER INDEX idx_join DISABLE;
+SELECT show_index_status('idx_join');
+ show_index_status  
+--------------------
+ (idx_join,t,t,t,f)
+(1 row)
+
+REINDEX INDEX CONCURRENTLY idx_join;
+SELECT show_index_status('idx_join');
+ show_index_status  
+--------------------
+ (idx_join,t,t,t,f)
+(1 row)
+
+SELECT pg_get_indexdef('idx_join'::regclass);
+                                  pg_get_indexdef                                  
+-----------------------------------------------------------------------------------
+ CREATE INDEX idx_join ON schema_to_reindex.join_test USING btree (ref_id) DISABLE
+(1 row)
+
+ALTER INDEX idx_join ENABLE;
+SELECT pg_get_indexdef('idx_join'::regclass);
+                              pg_get_indexdef                              
+---------------------------------------------------------------------------
+ CREATE INDEX idx_join ON schema_to_reindex.join_test USING btree (ref_id)
+(1 row)
+
+-- Test enable/disable index with indcheckxmin being true
+CREATE TABLE indcheckxmin_test(id int PRIMARY KEY);
+INSERT INTO indcheckxmin_test VALUES (1), (2), (3);
+CREATE INDEX CONCURRENTLY idx_checkxmin ON indcheckxmin_test(id);
+BEGIN;
+-- Simulate indcheckxmin being true
+UPDATE pg_index SET indcheckxmin = true WHERE indexrelid = 'idx_checkxmin'::regclass;
+ALTER INDEX idx_checkxmin DISABLE;  -- expect fail
+ERROR:  cannot enable/disable index while indcheckxmin is true
+HINT:  Wait for all transactions that might see inconsistent HOT chains to complete
+ROLLBACK;
+-- Clean up
+DROP TABLE index_test;
+DROP TABLE join_test;
+DROP FUNCTION get_data_length;
+DROP FUNCTION show_index_status;
+DROP TABLE indcheckxmin_test CASCADE;
 -- Failure for unauthorized user
 CREATE ROLE regress_reindexuser NOLOGIN;
 SET SESSION ROLE regress_reindexuser;
diff --git a/src/test/regress/sql/create_index.sql b/src/test/regress/sql/create_index.sql
index 6b3852dddd8..48569a0924a 100644
--- a/src/test/regress/sql/create_index.sql
+++ b/src/test/regress/sql/create_index.sql
@@ -1435,6 +1435,198 @@ END;
 -- concurrently
 REINDEX SCHEMA CONCURRENTLY schema_to_reindex;
 
+-- Test enable/disable functionality for indexes
+
+CREATE TABLE index_test(
+    id INT PRIMARY KEY,
+    data TEXT,
+    num INT,
+    vector INT[],
+    range INT4RANGE
+);
+
+INSERT INTO index_test
+SELECT
+    g,
+    'data ' || g,
+    g % 100,
+    ARRAY[g, g+1, g+2],
+    int4range(g, g+10)
+FROM generate_series(1, 1000) g;
+
+-- Function for testing
+CREATE FUNCTION get_data_length(text) RETURNS INT AS $$
+    SELECT length($1);
+$$ LANGUAGE SQL IMMUTABLE;
+
+-- Helper function to show index status
+CREATE OR REPLACE FUNCTION show_index_status(index_name text)
+RETURNS TABLE (
+    indexrelid regclass,
+    indisvalid boolean,
+    indisready boolean,
+    indislive boolean,
+    indisenabled boolean
+) AS $$
+BEGIN
+    RETURN QUERY EXECUTE format('
+        SELECT indexrelid::regclass, indisvalid, indisready, indislive, indisenabled
+        FROM pg_index
+        WHERE indexrelid = %L::regclass', index_name);
+END;
+$$ LANGUAGE plpgsql;
+
+-- Create and test each index type
+-- 1. Basic single-column index
+CREATE INDEX idx_single ON index_test(data);
+SELECT show_index_status('idx_single');
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE data = 'data 500';
+ALTER INDEX idx_single DISABLE;
+SELECT show_index_status('idx_single');
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE data = 'data 500';
+ALTER INDEX idx_single ENABLE;
+SELECT show_index_status('idx_single');
+
+-- 2. Multi-column index
+CREATE INDEX idx_multi ON index_test(num, data);
+SELECT show_index_status('idx_multi');
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE num = 50 AND data > 'data 500';
+ALTER INDEX idx_multi DISABLE;
+SELECT show_index_status('idx_multi');
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE num = 50 AND data > 'data 500';
+ALTER INDEX idx_multi ENABLE;
+SELECT show_index_status('idx_multi');
+
+-- 3. Partial index
+CREATE INDEX idx_partial ON index_test(num) WHERE num < 50;
+SELECT show_index_status('idx_partial');
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE num = 25;
+ALTER INDEX idx_partial DISABLE;
+SELECT show_index_status('idx_partial');
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE num = 25;
+ALTER INDEX idx_partial ENABLE;
+SELECT show_index_status('idx_partial');
+
+-- 4. Expression index
+CREATE INDEX idx_expression ON index_test((lower(data)));
+SELECT show_index_status('idx_expression');
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE lower(data) = 'data 500';
+ALTER INDEX idx_expression DISABLE;
+SELECT show_index_status('idx_expression');
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE lower(data) = 'data 500';
+ALTER INDEX idx_expression ENABLE;
+SELECT show_index_status('idx_expression');
+
+-- 5. GIN index
+CREATE INDEX idx_gin ON index_test USING gin(vector);
+SELECT show_index_status('idx_gin');
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE vector @> ARRAY[500];
+ALTER INDEX idx_gin DISABLE;
+SELECT show_index_status('idx_gin');
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE vector @> ARRAY[500];
+ALTER INDEX idx_gin ENABLE;
+SELECT show_index_status('idx_gin');
+
+-- 6. GiST index
+CREATE INDEX idx_gist ON index_test USING gist(range);
+SELECT show_index_status('idx_gist');
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE range && int4range(100, 110);
+ALTER INDEX idx_gist DISABLE;
+SELECT show_index_status('idx_gist');
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE range && int4range(100, 110);
+ALTER INDEX idx_gist ENABLE;
+SELECT show_index_status('idx_gist');
+
+-- 7. Covering index
+CREATE INDEX idx_covering ON index_test(num) INCLUDE (data);
+SELECT show_index_status('idx_covering');
+EXPLAIN (COSTS OFF) SELECT num, data FROM index_test WHERE num = 50;
+ALTER INDEX idx_covering DISABLE;
+SELECT show_index_status('idx_covering');
+EXPLAIN (COSTS OFF) SELECT num, data FROM index_test WHERE num = 50;
+ALTER INDEX idx_covering ENABLE;
+SELECT show_index_status('idx_covering');
+
+-- 8. Unique index
+CREATE UNIQUE INDEX idx_unique ON index_test(id, data);
+SELECT show_index_status('idx_unique');
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE id = 500 AND data = 'data 500';
+ALTER INDEX idx_unique DISABLE;
+SELECT show_index_status('idx_unique');
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE id = 500 AND data = 'data 500';
+ALTER INDEX idx_unique ENABLE;
+SELECT show_index_status('idx_unique');
+
+-- 9. Function-based index
+CREATE INDEX idx_func ON index_test(get_data_length(data));
+SELECT show_index_status('idx_func');
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE get_data_length(data) = 10;
+ALTER INDEX idx_func DISABLE;
+SELECT show_index_status('idx_func');
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE get_data_length(data) = 10;
+ALTER INDEX idx_func ENABLE;
+SELECT show_index_status('idx_func');
+
+-- 10. Join index
+CREATE TABLE join_test (id INT PRIMARY KEY, ref_id INT);
+INSERT INTO join_test SELECT g, g % 100 FROM generate_series(1, 1000) g;
+CREATE INDEX idx_join ON join_test(ref_id);
+SELECT show_index_status('idx_join');
+
+EXPLAIN (COSTS OFF)
+SELECT jt.id, it.data
+FROM join_test jt
+JOIN index_test it ON jt.ref_id = it.num
+WHERE jt.id BETWEEN 100 AND 200;
+
+-- Disable all indexes to force seq scan
+ALTER INDEX idx_join DISABLE;
+ALTER INDEX join_test_pkey DISABLE;
+SELECT show_index_status('idx_join');
+SELECT show_index_status('join_test_pkey');
+
+EXPLAIN (COSTS OFF)
+SELECT jt.id, it.data
+FROM join_test jt
+JOIN index_test it ON jt.ref_id = it.num
+WHERE jt.id BETWEEN 100 AND 200;
+
+ALTER INDEX idx_join ENABLE;
+ALTER INDEX join_test_pkey ENABLE;
+SELECT show_index_status('idx_join');
+SELECT show_index_status('join_test_pkey');
+
+-- Test REINDEX CONCURRENTLY
+REINDEX INDEX CONCURRENTLY idx_join;
+SELECT show_index_status('idx_join');
+
+ALTER INDEX idx_join DISABLE;
+SELECT show_index_status('idx_join');
+REINDEX INDEX CONCURRENTLY idx_join;
+SELECT show_index_status('idx_join');
+
+SELECT pg_get_indexdef('idx_join'::regclass);
+ALTER INDEX idx_join ENABLE;
+SELECT pg_get_indexdef('idx_join'::regclass);
+
+-- Test enable/disable index with indcheckxmin being true
+
+CREATE TABLE indcheckxmin_test(id int PRIMARY KEY);
+INSERT INTO indcheckxmin_test VALUES (1), (2), (3);
+CREATE INDEX CONCURRENTLY idx_checkxmin ON indcheckxmin_test(id);
+BEGIN;
+-- Simulate indcheckxmin being true
+UPDATE pg_index SET indcheckxmin = true WHERE indexrelid = 'idx_checkxmin'::regclass;
+ALTER INDEX idx_checkxmin DISABLE;  -- expect fail
+ROLLBACK;
+
+-- Clean up
+DROP TABLE index_test;
+DROP TABLE join_test;
+DROP FUNCTION get_data_length;
+DROP FUNCTION show_index_status;
+DROP TABLE indcheckxmin_test CASCADE;
+
 -- Failure for unauthorized user
 CREATE ROLE regress_reindexuser NOLOGIN;
 SET SESSION ROLE regress_reindexuser;
-- 
2.39.5 (Apple Git-154)

#77Shayon Mukherjee
shayonj@gmail.com
In reply to: Sami Imseih (#76)
1 attachment(s)
Re: Proposal to Enable/Disable Index using ALTER INDEX (with patch)

On Tue, Apr 1, 2025 at 2:41 PM Sami Imseih <samimseih@gmail.com> wrote:

I went back to look at this patch and a few things. I noticed it did
not have correct
indentation, so I ran pgindent. I also removed some extra lines added and
made
some slight adjustments to the docs. Attached my edited patch as a txt. If
you
agree, please revise into a v14.

I also noticed that between v12 and v13, the GUC use_invisible_index
was removed,
but I don't see a discussion as to why. I feel it's a good GUC to have
[0], and we should
at least have it as a separate patch as part of this set.

My apologies, I rebased off an old commit and that's how we lost the GUC
change and also the rename from ENABLE/DISABLE to VISIBLE/INVISIBLE. I have
brought it all back, in addition to the specs and other changes mentioned
in v12. Let me know if you have any feedback, more than happy to
incorporate them.

Also, thank you for letting me know of pgindent, very handy!

I will continue reviewing the patch, but i feel this may be close to

be marked RFC, although
not sure if it will get a committer review before code freeze.

I really appreciate the reviews and guidance, thank you! Would love if this
can become part of v18 release. No worries if not of course. I am
definitely around to help get this production ready and also if any issues
arise after.

Thank you
Shayon

Attachments:

v14-0001-Introduce-the-ability-to-set-index-visibility-us.patchapplication/octet-stream; name=v14-0001-Introduce-the-ability-to-set-index-visibility-us.patchDownload
From 491f89a77c1675aa5b96018d8bf4211d90673763 Mon Sep 17 00:00:00 2001
From: Shayon Mukherjee <shayonj@gmail.com>
Date: Sun, 12 Jan 2025 14:34:48 -0500
Subject: [PATCH v14] Introduce the ability to set index visibility using ALTER
 INDEX

This patch introduces index visibility control using ALTER INDEX and CREATE INDEX
commands.

Original motivation for the problem and proposal for a patch
can be found at [1].

This patch passes all the existing specs and the newly added regression tests. The patch
is ready for review and test. It compiles, so the patch can be applied for testing as well.

Note: The patch has gone through a few iterations. Earlier versions of the patch had the ENABLE/DISABLE grammar.
The current version has the VISIBLE/INVISIBLE grammar. So, you will the local variable names using the new grammar accordingly.

Implementation details:

- New Grammar:
  * ALTER INDEX ... VISIBLE/INVISIBLE
  * CREATE INDEX ... INVISIBLE

- Default state is visible. Indexes are only invisible when explicitly
  instructed via CREATE INDEX ... INVISIBLE or ALTER INDEX ... INVISIBLE.

- Primary Key and Unique constraint indexes are always visible. The
  VISIBLE/INVISIBLE grammar is supported for these types of indexes and they can
  be made invisible via ALTER INDEX ... INVISIBLE.

- ALTER INDEX ... VISIBLE/INVISIBLE performs update on the relevant row in pg_index
  catalog

- pg_get_indexdef() supports the new functionality and grammar. This change is
  reflected in \d output for tables and pg_dump. We show the INVISIBLE syntax accordingly.

- Added force_invisible_index GUC parameter that forces the planner to use invisible
  indexes. This is useful for testing and validating index behavior without changing
  their visibility state. Based on feedback from Sami S [2]

- Updated create_index.sql regression test to cover the new grammar and verify
  that invisible indexes are not used in queries. The test covers:

  - Basic single-column and multi-column indexes
  - Partial indexes
  - Expression indexes
  - Join indexes
  - GIN and GiST indexes
  - Covering indexes
  - Range indexes
  - Unique indexes and constraints

- Adds a new indisvisible attribute to the IndexOptInfo structure.

- Modifies get_relation_info in plancat.c to skip invisible indexes entirely, thus reducing the number of places we need to check if an index is invisible or not. Inspired by the conversations start at [3].
  - I chose to modify the logic within get_relation_info as compared to, say, reducing the cost to make the planner not consider an index during planning, mostly to keep the number of changes being introduced to a minimum and also the logic itself being self-contained and easier to understand perhaps (?).

- No changes are made to stop the index from getting maintained. This way we ensure no
  data loss or corruption when index is made visible again.

- TOAST indexes are supported and visible by default as well.

- REINDEX CONCURRENTLY is supported as well and existing state of pg_index.indisvisible
  is carried over accordingly.

- See the changes in create_index.sql to get an idea of the grammar and sql statements.

- See the changes in create_index.out to get an idea of the catalogue states and EXPLAIN
  output to see when an index is getting used or isn't (when invisible).

- Incorporated DavidR's feedback from [4] around documentation and also you will see that by skipping invisible indexes entirely from get_relation_info in plancat.c (as mentioned above), we address the other mentioned issues as well.

- Lastly, protects against the case where indcheckxmin is true by raising ERRCODE_OBJECT_NOT_IN_PREREQUISITE_STATE.

Looking forward to any and all feedback on this patch, including but not limited to code quality, tests, fundamental logic.

[1] https://www.postgresql.org/message-id/CANqtF-oXKe0M%3D0QOih6H%2BsZRjE2BWAbkW_1%2B9nMEAMLxUJg5jA%40mail.gmail.com
[2] https://www.postgresql.org/message-id/CAA5RZ0udzydObMDi65C59-oq54B9ZmjSZ1wVH3h%2Bv4XiVm6QDA%40mail.gmail.com
[3] https://www.postgresql.org/message-id/3465209.1727202064%40sss.pgh.pa.us
[4] https://www.postgresql.org/message-id/CAApHDvpUNu%3DiVcdJ74sypvgeaCF%2Btfpyb8VRhZaF7DTd1xVr7g%40mail.gmail.com
---
 doc/src/sgml/catalogs.sgml                    |  11 +
 doc/src/sgml/config.sgml                      |  16 +
 doc/src/sgml/ref/alter_index.sgml             |  38 +
 doc/src/sgml/ref/create_index.sgml            |  29 +
 src/backend/bootstrap/bootparse.y             |   2 +
 src/backend/catalog/index.c                   |  31 +-
 src/backend/catalog/toasting.c                |   2 +-
 src/backend/commands/indexcmds.c              |   4 +
 src/backend/commands/tablecmds.c              |  92 +-
 src/backend/optimizer/util/plancat.c          |  30 +-
 src/backend/parser/gram.y                     |  56 +-
 src/backend/parser/parse_utilcmd.c            |   3 +
 src/backend/utils/adt/ruleutils.c             |   4 +
 src/backend/utils/cache/relcache.c            |   1 +
 src/backend/utils/misc/guc_tables.c           |  10 +
 src/backend/utils/misc/postgresql.conf.sample |   1 +
 src/bin/pg_dump/pg_dump.c                     |  21 +-
 src/bin/pg_dump/pg_dump.h                     |   2 +
 src/bin/pg_dump/t/002_pg_dump.pl              |  29 +
 src/bin/psql/describe.c                       |  15 +-
 src/bin/psql/tab-complete.in.c                |   3 +-
 src/include/catalog/index.h                   |   2 +-
 src/include/catalog/pg_index.h                |   2 +
 src/include/nodes/parsenodes.h                |   4 +
 src/include/optimizer/optimizer.h             |   5 +
 src/include/parser/kwlist.h                   |   2 +
 src/include/utils/guc_hooks.h                 |   1 +
 src/test/modules/test_ddl_deparse/Makefile    |   3 +-
 .../test_ddl_deparse/expected/alter_index.out |  29 +
 src/test/modules/test_ddl_deparse/meson.build |   1 +
 .../test_ddl_deparse/sql/alter_index.sql      |  18 +
 .../test_ddl_deparse/test_ddl_deparse.c       |   6 +
 src/test/regress/expected/create_index.out    | 795 ++++++++++++++++++
 src/test/regress/sql/create_index.sql         | 321 +++++++
 34 files changed, 1563 insertions(+), 26 deletions(-)
 create mode 100644 src/test/modules/test_ddl_deparse/expected/alter_index.out
 create mode 100644 src/test/modules/test_ddl_deparse/sql/alter_index.sql

diff --git a/doc/src/sgml/catalogs.sgml b/doc/src/sgml/catalogs.sgml
index fb05063555..3ca0d54fc3 100644
--- a/doc/src/sgml/catalogs.sgml
+++ b/doc/src/sgml/catalogs.sgml
@@ -4618,6 +4618,17 @@ SCRAM-SHA-256$<replaceable>&lt;iteration count&gt;</replaceable>:<replaceable>&l
        partial index.
       </para></entry>
      </row>
+
+     <row>
+      <entry role="catalog_table_entry"><para role="column_definition">
+       <structfield>indisvisible</structfield> <type>bool</type>
+      </para>
+      <para>
+       If true, the index is currently visible to the planner and may be used for queries.
+       If false, the index is invisible and may not be used for queries,
+       but is still updated when the table is modified. Default is true.
+      </para></entry>
+     </row>
     </tbody>
    </tgroup>
   </table>
diff --git a/doc/src/sgml/config.sgml b/doc/src/sgml/config.sgml
index fea683cb49..b0925baf90 100644
--- a/doc/src/sgml/config.sgml
+++ b/doc/src/sgml/config.sgml
@@ -5778,6 +5778,22 @@ ANY <replaceable class="parameter">num_sync</replaceable> ( <replaceable class="
       </listitem>
      </varlistentry>
 
+     <varlistentry id="guc-force-invisible-index" xreflabel="use_invisible_index">
+      <term><varname>use_invisible_index</varname> (<type>boolean</type>)
+      <indexterm>
+       <primary><varname>use_invisible_index</varname> configuration parameter</primary>
+      </indexterm>
+      </term>
+      <listitem>
+       <para>
+        Forces the query planner to consider indexes that have been marked as invisible using
+        <command>ALTER INDEX ... INVISIBLE</command>. This parameter is useful for selective
+        use of invisible indexes in specific application contexts. The default
+        is <literal>off</literal>.
+       </para>
+      </listitem>
+     </varlistentry>
+
      </variablelist>
      </sect2>
      <sect2 id="runtime-config-query-constants">
diff --git a/doc/src/sgml/ref/alter_index.sgml b/doc/src/sgml/ref/alter_index.sgml
index 1d42d05d85..d26e7761c1 100644
--- a/doc/src/sgml/ref/alter_index.sgml
+++ b/doc/src/sgml/ref/alter_index.sgml
@@ -31,6 +31,7 @@ ALTER INDEX [ IF EXISTS ] <replaceable class="parameter">name</replaceable> ALTE
     SET STATISTICS <replaceable class="parameter">integer</replaceable>
 ALTER INDEX ALL IN TABLESPACE <replaceable class="parameter">name</replaceable> [ OWNED BY <replaceable class="parameter">role_name</replaceable> [, ... ] ]
     SET TABLESPACE <replaceable class="parameter">new_tablespace</replaceable> [ NOWAIT ]
+ALTER INDEX [ IF EXISTS ] <replaceable class="parameter">name</replaceable> { VISIBLE | INVISIBLE }
 </synopsis>
  </refsynopsisdiv>
 
@@ -159,6 +160,29 @@ ALTER INDEX ALL IN TABLESPACE <replaceable class="parameter">name</replaceable>
     </listitem>
    </varlistentry>
 
+   <varlistentry>
+    <term><literal>VISIBLE</literal></term>
+    <listitem>
+     <para>
+      Make the specified index visible. The index will be used for query planning.
+     </para>
+    </listitem>
+   </varlistentry>
+
+   <varlistentry>
+    <term><literal>INVISIBLE</literal></term>
+    <listitem>
+     <para>
+      Make the specified index invisible. The index will not be used for queries.
+      This can be useful for testing query performance with and without specific
+      indexes. If performance degrades after making an index invisible, it can be easily
+      be made visible using <literal>VISIBLE</literal>. Before making an index invisible, it's recommended
+      to check <structname>pg_stat_user_indexes</structname>.<structfield>idx_scan</structfield>
+      to identify potentially unused indexes.
+     </para>
+    </listitem>
+   </varlistentry>
+
   </variablelist>
   </para>
 
@@ -301,6 +325,20 @@ CREATE INDEX coord_idx ON measured (x, y, (z + t));
 ALTER INDEX coord_idx ALTER COLUMN 3 SET STATISTICS 1000;
 </programlisting></para>
 
+  <para>
+   To make an index visible:
+<programlisting>
+ALTER INDEX idx_name VISIBLE;
+</programlisting>
+  </para>
+
+  <para>
+   To make an index invisible:
+<programlisting>
+ALTER INDEX idx_name INVISIBLE;
+</programlisting>
+  </para>
+
  </refsect1>
 
  <refsect1>
diff --git a/doc/src/sgml/ref/create_index.sgml b/doc/src/sgml/ref/create_index.sgml
index 208389e800..90d7d90a2b 100644
--- a/doc/src/sgml/ref/create_index.sgml
+++ b/doc/src/sgml/ref/create_index.sgml
@@ -28,6 +28,7 @@ CREATE [ UNIQUE ] INDEX [ CONCURRENTLY ] [ [ IF NOT EXISTS ] <replaceable class=
     [ WITH ( <replaceable class="parameter">storage_parameter</replaceable> [= <replaceable class="parameter">value</replaceable>] [, ... ] ) ]
     [ TABLESPACE <replaceable class="parameter">tablespace_name</replaceable> ]
     [ WHERE <replaceable class="parameter">predicate</replaceable> ]
+    [ INVISIBLE ]
 </synopsis>
  </refsynopsisdiv>
 
@@ -380,6 +381,19 @@ CREATE [ UNIQUE ] INDEX [ CONCURRENTLY ] [ [ IF NOT EXISTS ] <replaceable class=
       </listitem>
      </varlistentry>
 
+    <varlistentry>
+      <term><literal>INVISIBLE</literal></term>
+      <listitem>
+       <para>
+        Creates the index in an invisible state (default visible). An invisible index is
+        not used by the query planner for queries, but it is still maintained
+        when the underlying table data changes. This can be useful when you want to create
+        an index without immediately impacting query planning, allowing you to make it
+        visible later at a more convenient time. The index can be made visible later
+        using <command>ALTER INDEX ... VISIBLE</command>.
+       </para>
+      </listitem>
+     </varlistentry>
     </variablelist>
 
   <refsect2 id="sql-createindex-storage-parameters" xreflabel="Index Storage Parameters">
@@ -701,6 +715,14 @@ Indexes:
     partitioned index is a metadata only operation.
    </para>
 
+  <para>
+   When creating an index with the <literal>INVISIBLE</literal> option, the index
+   will be created but not used for query planning. This can be useful for
+   preparing an index in advance of its use, or for testing purposes. The index
+   will still be maintained as the table is modified, so it can be made visible
+   later without needing to be rebuilt. By default all new indexes are visible.
+  </para>
+
   </refsect2>
  </refsect1>
 
@@ -980,6 +1002,13 @@ SELECT * FROM points
 CREATE INDEX CONCURRENTLY sales_quantity_index ON sales_table (quantity);
 </programlisting></para>
 
+  <para>
+   To create an index on the table <literal>test_table</literal> with the default
+   name, but have it initially invisible:
+<programlisting>
+CREATE INDEX ON test_table (col1) INVISIBLE;
+</programlisting>
+  </para>
  </refsect1>
 
  <refsect1>
diff --git a/src/backend/bootstrap/bootparse.y b/src/backend/bootstrap/bootparse.y
index 9833f52c1b..ea21511a20 100644
--- a/src/backend/bootstrap/bootparse.y
+++ b/src/backend/bootstrap/bootparse.y
@@ -303,6 +303,7 @@ Boot_DeclareIndexStmt:
 					stmt->concurrent = false;
 					stmt->if_not_exists = false;
 					stmt->reset_default_tblspc = false;
+					stmt->isvisible = true;
 
 					/* locks and races need not concern us in bootstrap mode */
 					relationId = RangeVarGetRelid(stmt->relation, NoLock,
@@ -356,6 +357,7 @@ Boot_DeclareUniqueIndexStmt:
 					stmt->concurrent = false;
 					stmt->if_not_exists = false;
 					stmt->reset_default_tblspc = false;
+					stmt->isvisible = true;
 
 					/* locks and races need not concern us in bootstrap mode */
 					relationId = RangeVarGetRelid(stmt->relation, NoLock,
diff --git a/src/backend/catalog/index.c b/src/backend/catalog/index.c
index 739a92bdcc..2d8ceb60ce 100644
--- a/src/backend/catalog/index.c
+++ b/src/backend/catalog/index.c
@@ -119,7 +119,8 @@ static void UpdateIndexRelation(Oid indexoid, Oid heapoid,
 								bool isexclusion,
 								bool immediate,
 								bool isvalid,
-								bool isready);
+								bool isready,
+								bool isvisible);
 static void index_update_stats(Relation rel,
 							   bool hasindex,
 							   double reltuples);
@@ -571,7 +572,8 @@ UpdateIndexRelation(Oid indexoid,
 					bool isexclusion,
 					bool immediate,
 					bool isvalid,
-					bool isready)
+					bool isready,
+					bool isvisible)
 {
 	int2vector *indkey;
 	oidvector  *indcollation;
@@ -649,6 +651,7 @@ UpdateIndexRelation(Oid indexoid,
 	values[Anum_pg_index_indisready - 1] = BoolGetDatum(isready);
 	values[Anum_pg_index_indislive - 1] = BoolGetDatum(true);
 	values[Anum_pg_index_indisreplident - 1] = BoolGetDatum(false);
+	values[Anum_pg_index_indisvisible - 1] = BoolGetDatum(isvisible);
 	values[Anum_pg_index_indkey - 1] = PointerGetDatum(indkey);
 	values[Anum_pg_index_indcollation - 1] = PointerGetDatum(indcollation);
 	values[Anum_pg_index_indclass - 1] = PointerGetDatum(indclass);
@@ -714,6 +717,8 @@ UpdateIndexRelation(Oid indexoid,
  *			already exists.
  *		INDEX_CREATE_PARTITIONED:
  *			create a partitioned index (table must be partitioned)
+ *		INDEX_CREATE_VISIBLE:
+ *			create the index as visible to query planner
  * constr_flags: flags passed to index_constraint_create
  *		(only if INDEX_CREATE_ADD_CONSTRAINT is set)
  * allow_system_table_mods: allow table to be a system catalog
@@ -759,6 +764,7 @@ index_create(Relation heapRelation,
 	bool		invalid = (flags & INDEX_CREATE_INVALID) != 0;
 	bool		concurrent = (flags & INDEX_CREATE_CONCURRENT) != 0;
 	bool		partitioned = (flags & INDEX_CREATE_PARTITIONED) != 0;
+	bool		isvisible = (flags & INDEX_CREATE_VISIBLE) != 0;
 	char		relkind;
 	TransactionId relfrozenxid;
 	MultiXactId relminmxid;
@@ -1042,13 +1048,15 @@ index_create(Relation heapRelation,
 	 *	  (Or, could define a rule to maintain the predicate) --Nels, Feb '92
 	 * ----------------
 	 */
+
 	UpdateIndexRelation(indexRelationId, heapRelationId, parentIndexRelid,
 						indexInfo,
 						collationIds, opclassIds, coloptions,
 						isprimary, is_exclusion,
 						(constr_flags & INDEX_CONSTR_CREATE_DEFERRABLE) == 0,
 						!concurrent && !invalid,
-						!concurrent);
+						!concurrent,
+						isvisible);
 
 	/*
 	 * Register relcache invalidation on the indexes' heap relation, to
@@ -1317,6 +1325,8 @@ index_concurrently_create_copy(Relation heapRelation, Oid oldIndexId,
 	List	   *indexColNames = NIL;
 	List	   *indexExprs = NIL;
 	List	   *indexPreds = NIL;
+	Form_pg_index indexForm;
+	bits16		createFlags;
 
 	indexRelation = index_open(oldIndexId, RowExclusiveLock);
 
@@ -1344,6 +1354,9 @@ index_concurrently_create_copy(Relation heapRelation, Oid oldIndexId,
 											Anum_pg_index_indoption);
 	indcoloptions = (int2vector *) DatumGetPointer(colOptionDatum);
 
+	/* Get the visibility state of the original index */
+	indexForm = (Form_pg_index) GETSTRUCT(indexTuple);
+
 	/* Fetch reloptions of index if any */
 	classTuple = SearchSysCache1(RELOID, ObjectIdGetDatum(oldIndexId));
 	if (!HeapTupleIsValid(classTuple))
@@ -1435,6 +1448,16 @@ index_concurrently_create_copy(Relation heapRelation, Oid oldIndexId,
 		stattargets[i].isnull = isnull;
 	}
 
+	/*
+	 * Determine the create flags for the new index. We always use SKIP_BUILD
+	 * and CONCURRENT for concurrent reindexing. If the original index was
+	 * visible, we also set the VISIBLE flag to maintain the same state in the
+	 * new index.
+	 */
+	createFlags = INDEX_CREATE_SKIP_BUILD | INDEX_CREATE_CONCURRENT;
+	if (indexForm->indisvisible)
+		createFlags |= INDEX_CREATE_VISIBLE;
+
 	/*
 	 * Now create the new index.
 	 *
@@ -1458,7 +1481,7 @@ index_concurrently_create_copy(Relation heapRelation, Oid oldIndexId,
 							  indcoloptions->values,
 							  stattargets,
 							  reloptionsDatum,
-							  INDEX_CREATE_SKIP_BUILD | INDEX_CREATE_CONCURRENT,
+							  createFlags,
 							  0,
 							  true, /* allow table to be a system catalog? */
 							  false,	/* is_internal? */
diff --git a/src/backend/catalog/toasting.c b/src/backend/catalog/toasting.c
index 874a8fc89a..7721d16fd3 100644
--- a/src/backend/catalog/toasting.c
+++ b/src/backend/catalog/toasting.c
@@ -325,7 +325,7 @@ create_toast_table(Relation rel, Oid toastOid, Oid toastIndexOid,
 				 BTREE_AM_OID,
 				 rel->rd_rel->reltablespace,
 				 collationIds, opclassIds, NULL, coloptions, NULL, (Datum) 0,
-				 INDEX_CREATE_IS_PRIMARY, 0, true, true, NULL);
+				 INDEX_CREATE_IS_PRIMARY | INDEX_CREATE_VISIBLE, 0, true, true, NULL);
 
 	table_close(toast_rel, NoLock);
 
diff --git a/src/backend/commands/indexcmds.c b/src/backend/commands/indexcmds.c
index 33c2106c17..693f23e8d6 100644
--- a/src/backend/commands/indexcmds.c
+++ b/src/backend/commands/indexcmds.c
@@ -1222,6 +1222,10 @@ DefineIndex(Oid tableId,
 		flags |= INDEX_CREATE_PARTITIONED;
 	if (stmt->primary)
 		flags |= INDEX_CREATE_IS_PRIMARY;
+	if (stmt->isvisible)
+		flags |= INDEX_CREATE_VISIBLE;
+	else
+		flags &= ~INDEX_CREATE_VISIBLE;
 
 	/*
 	 * If the table is partitioned, and recursion was declined but partitions
diff --git a/src/backend/commands/tablecmds.c b/src/backend/commands/tablecmds.c
index 10624353b0..ab8405b4ce 100644
--- a/src/backend/commands/tablecmds.c
+++ b/src/backend/commands/tablecmds.c
@@ -719,7 +719,8 @@ static List *GetParentedForeignKeyRefs(Relation partition);
 static void ATDetachCheckNoForeignKeyRefs(Relation partition);
 static char GetAttributeCompression(Oid atttypid, const char *compression);
 static char GetAttributeStorage(Oid atttypid, const char *storagemode);
-
+static void ATExecSetIndexVisibility(Relation rel, bool visible);
+static bool GetIndexVisibility(Oid indexOid);
 
 /* ----------------------------------------------------------------
  *		DefineRelation
@@ -4814,6 +4815,11 @@ AlterTableGetLockLevel(List *cmds)
 				cmd_lockmode = ShareUpdateExclusiveLock;
 				break;
 
+			case AT_SetIndexVisible:
+			case AT_SetIndexInvisible:
+				cmd_lockmode = ShareUpdateExclusiveLock;
+				break;
+
 			default:			/* oops */
 				elog(ERROR, "unrecognized alter table type: %d",
 					 (int) cmd->subtype);
@@ -5249,6 +5255,13 @@ ATPrepCmd(List **wqueue, Relation rel, AlterTableCmd *cmd,
 			/* No command-specific prep needed */
 			pass = AT_PASS_MISC;
 			break;
+		case AT_SetIndexVisible:
+		case AT_SetIndexInvisible:
+			ATSimplePermissions(cmd->subtype, rel, ATT_INDEX | ATT_PARTITIONED_INDEX);
+			ATSimpleRecursion(wqueue, rel, cmd, true, lockmode, context);
+			/* No command-specific prep needed */
+			pass = AT_PASS_MISC;
+			break;
 		default:				/* oops */
 			elog(ERROR, "unrecognized alter table type: %d",
 				 (int) cmd->subtype);
@@ -5645,6 +5658,12 @@ ATExecCmd(List **wqueue, AlteredTableInfo *tab,
 		case AT_DetachPartitionFinalize:
 			address = ATExecDetachPartitionFinalize(rel, ((PartitionCmd *) cmd->def)->name);
 			break;
+		case AT_SetIndexVisible:
+			ATExecSetIndexVisibility(rel, true);
+			break;
+		case AT_SetIndexInvisible:
+			ATExecSetIndexVisibility(rel, false);
+			break;
 		default:				/* oops */
 			elog(ERROR, "unrecognized alter table type: %d",
 				 (int) cmd->subtype);
@@ -6591,6 +6610,8 @@ alter_table_type_to_string(AlterTableType cmdtype)
 			return "DROP COLUMN";
 		case AT_AddIndex:
 		case AT_ReAddIndex:
+		case AT_SetIndexVisible:
+		case AT_SetIndexInvisible:
 			return NULL;		/* not real grammar */
 		case AT_AddConstraint:
 		case AT_ReAddConstraint:
@@ -15088,6 +15109,8 @@ ATPostAlterTypeParse(Oid oldId, Oid oldRelId, Oid refRelId, char *cmd,
 			stmt->reset_default_tblspc = true;
 			/* keep the index's comment */
 			stmt->idxcomment = GetComment(oldId, RelationRelationId, 0);
+			/* preserve the index's visibility status */
+			stmt->isvisible = GetIndexVisibility(oldId);
 
 			newcmd = makeNode(AlterTableCmd);
 			newcmd->subtype = AT_ReAddIndex;
@@ -15118,6 +15141,8 @@ ATPostAlterTypeParse(Oid oldId, Oid oldRelId, Oid refRelId, char *cmd,
 					indstmt->idxcomment = GetComment(indoid,
 													 RelationRelationId, 0);
 					indstmt->reset_default_tblspc = true;
+					/* preserve the index's visibility status */
+					indstmt->isvisible = GetIndexVisibility(indoid);
 
 					cmd->subtype = AT_ReAddIndex;
 					tab->subcmds[AT_PASS_OLD_INDEX] =
@@ -21466,3 +21491,68 @@ GetAttributeStorage(Oid atttypid, const char *storagemode)
 
 	return cstorage;
 }
+
+/*
+ * ATExecSetIndexVisibility
+ * Performs a catalog update to mark an index as visible or invisible in pg_index.
+ */
+static void
+ATExecSetIndexVisibility(Relation rel, bool visible)
+{
+	Oid			indexOid = RelationGetRelid(rel);
+	Oid			heapOid;
+	Relation	pg_index;
+	Relation	heapRel;
+	HeapTuple	indexTuple;
+	Form_pg_index indexForm;
+
+	heapOid = IndexGetRelation(indexOid, false);
+	heapRel = table_open(heapOid, AccessShareLock);
+	pg_index = table_open(IndexRelationId, RowExclusiveLock);
+
+	indexTuple = SearchSysCacheCopy1(INDEXRELID, ObjectIdGetDatum(indexOid));
+	if (!HeapTupleIsValid(indexTuple))
+		elog(ERROR, "cache lookup failed for index %u", indexOid);
+
+	indexForm = (Form_pg_index) GETSTRUCT(indexTuple);
+	if (indexForm->indcheckxmin)
+		ereport(ERROR,
+				errcode(ERRCODE_OBJECT_NOT_IN_PREREQUISITE_STATE),
+				errmsg("cannot update index visibility while indcheckxmin is true"),
+				errhint("Wait for all transactions that might see inconsistent HOT chains to complete"));
+
+	if (indexForm->indisvisible != visible)
+	{
+		indexForm->indisvisible = visible;
+		CatalogTupleUpdate(pg_index, &indexTuple->t_self, indexTuple);
+
+		CacheInvalidateRelcache(heapRel);
+		InvokeObjectPostAlterHook(IndexRelationId, indexOid, 0);
+		CommandCounterIncrement();
+	}
+
+	heap_freetuple(indexTuple);
+	table_close(pg_index, RowExclusiveLock);
+	table_close(heapRel, AccessShareLock);
+}
+
+/*
+* Get index visibility status from pg_index
+*/
+static bool
+GetIndexVisibility(Oid indexOid)
+{
+	HeapTuple	indexTuple;
+	Form_pg_index indexForm;
+	bool		isvisible;
+
+	indexTuple = SearchSysCache1(INDEXRELID, ObjectIdGetDatum(indexOid));
+	if (!HeapTupleIsValid(indexTuple))
+		elog(ERROR, "cache lookup failed for index %u", indexOid);
+
+	indexForm = (Form_pg_index) GETSTRUCT(indexTuple);
+	isvisible = indexForm->indisvisible;
+	ReleaseSysCache(indexTuple);
+
+	return isvisible;
+}
diff --git a/src/backend/optimizer/util/plancat.c b/src/backend/optimizer/util/plancat.c
index 0489ad3664..3a38911328 100644
--- a/src/backend/optimizer/util/plancat.c
+++ b/src/backend/optimizer/util/plancat.c
@@ -47,7 +47,9 @@
 #include "storage/bufmgr.h"
 #include "tcop/tcopprot.h"
 #include "utils/builtins.h"
+#include "utils/guc_hooks.h"
 #include "utils/lsyscache.h"
+#include "utils/plancache.h"
 #include "utils/partcache.h"
 #include "utils/rel.h"
 #include "utils/snapmgr.h"
@@ -55,6 +57,7 @@
 
 /* GUC parameter */
 int			constraint_exclusion = CONSTRAINT_EXCLUSION_PARTITION;
+bool		use_invisible_index = false;
 
 /* Hook for plugins to get control in get_relation_info() */
 get_relation_info_hook_type get_relation_info_hook = NULL;
@@ -254,13 +257,13 @@ get_relation_info(PlannerInfo *root, Oid relationObjectId, bool inhparent,
 			index = indexRelation->rd_index;
 
 			/*
-			 * Ignore invalid indexes, since they can't safely be used for
-			 * queries.  Note that this is OK because the data structure we
-			 * are constructing is only used by the planner --- the executor
-			 * still needs to insert into "invalid" indexes, if they're marked
-			 * indisready.
+			 * Skip invalid indexes, and invisible indexes unless
+			 * use_invisible_index is set. This is OK because the data
+			 * structure we are constructing is only used by the planner - the
+			 * executor still needs to insert into these indexes if they're
+			 * marked indisready.
 			 */
-			if (!index->indisvalid)
+			if (!index->indisvalid || (!index->indisvisible && !use_invisible_index))
 			{
 				index_close(indexRelation, NoLock);
 				continue;
@@ -2610,3 +2613,18 @@ set_baserel_partition_constraint(Relation relation, RelOptInfo *rel)
 		rel->partition_qual = partconstr;
 	}
 }
+
+/*
+ * assign_use_invisible_index
+ * GUC assign_hook for "use_invisible_index" GUC variable.
+ * Resets the plan cache when the value changes.
+ */
+void
+assign_use_invisible_index(bool newval, void *extra)
+{
+	if (use_invisible_index != newval)
+	{
+		use_invisible_index = newval;
+		ResetPlanCache();
+	}
+}
diff --git a/src/backend/parser/gram.y b/src/backend/parser/gram.y
index 0fc502a3a4..7f46794eb7 100644
--- a/src/backend/parser/gram.y
+++ b/src/backend/parser/gram.y
@@ -324,7 +324,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 %type <ival>	add_drop opt_asc_desc opt_nulls_order
 
 %type <node>	alter_table_cmd alter_type_cmd opt_collate_clause
-	   replica_identity partition_cmd index_partition_cmd
+	   replica_identity partition_cmd index_partition_cmd index_alter_cmd
 %type <list>	alter_table_cmds alter_type_cmds
 %type <list>    alter_identity_column_option_list
 %type <defelt>  alter_identity_column_option
@@ -491,6 +491,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 %type <boolean> opt_unique opt_verbose opt_full
 %type <boolean> opt_freeze opt_analyze opt_default
 %type <defelt>	opt_binary copy_delimiter
+%type <boolean>  opt_index_visibility
 
 %type <boolean> copy_from opt_program
 
@@ -733,7 +734,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 	IDENTITY_P IF_P ILIKE IMMEDIATE IMMUTABLE IMPLICIT_P IMPORT_P IN_P INCLUDE
 	INCLUDING INCREMENT INDENT INDEX INDEXES INHERIT INHERITS INITIALLY INLINE_P
 	INNER_P INOUT INPUT_P INSENSITIVE INSERT INSTEAD INT_P INTEGER
-	INTERSECT INTERVAL INTO INVOKER IS ISNULL ISOLATION
+	INTERSECT INTERVAL INTO INVISIBLE INVOKER IS ISNULL ISOLATION
 
 	JOIN JSON JSON_ARRAY JSON_ARRAYAGG JSON_EXISTS JSON_OBJECT JSON_OBJECTAGG
 	JSON_QUERY JSON_SCALAR JSON_SERIALIZE JSON_TABLE JSON_VALUE
@@ -784,7 +785,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 	UNLISTEN UNLOGGED UNTIL UPDATE USER USING
 
 	VACUUM VALID VALIDATE VALIDATOR VALUE_P VALUES VARCHAR VARIADIC VARYING
-	VERBOSE VERSION_P VIEW VIEWS VIRTUAL VOLATILE
+	VERBOSE VERSION_P VIEW VIEWS VIRTUAL VISIBLE VOLATILE
 
 	WHEN WHERE WHITESPACE_P WINDOW WITH WITHIN WITHOUT WORK WRAPPER WRITE
 
@@ -2157,6 +2158,24 @@ AlterTableStmt:
 					n->nowait = $13;
 					$$ = (Node *) n;
 				}
+		| ALTER INDEX qualified_name index_alter_cmd
+				{
+					AlterTableStmt *n = makeNode(AlterTableStmt);
+					n->relation = $3;
+					n->cmds = list_make1($4);
+					n->objtype = OBJECT_INDEX;
+					n->missing_ok = false;
+					$$ = (Node *) n;
+				}
+		| ALTER INDEX IF_P EXISTS qualified_name index_alter_cmd
+				{
+					AlterTableStmt *n = makeNode(AlterTableStmt);
+					n->relation = $5;
+					n->cmds = list_make1($6);
+					n->objtype = OBJECT_INDEX;
+					n->missing_ok = true;
+					$$ = (Node *) n;
+				}
 		|	ALTER INDEX qualified_name alter_table_cmds
 				{
 					AlterTableStmt *n = makeNode(AlterTableStmt);
@@ -2382,6 +2401,21 @@ index_partition_cmd:
 				}
 		;
 
+index_alter_cmd:
+		/* ALTER INDEX <name> VISIBLE|INVISIBLE */
+		VISIBLE
+			{
+				AlterTableCmd *n = makeNode(AlterTableCmd);
+				n->subtype = AT_SetIndexVisible;
+				$$ = (Node *) n;
+			}
+		| INVISIBLE
+			{
+				AlterTableCmd *n = makeNode(AlterTableCmd);
+				n->subtype = AT_SetIndexInvisible;
+				$$ = (Node *) n;
+			}
+		;
 alter_table_cmd:
 			/* ALTER TABLE <name> ADD <coldef> */
 			ADD_P columnDef
@@ -8185,7 +8219,7 @@ defacl_privilege_target:
 
 IndexStmt:	CREATE opt_unique INDEX opt_concurrently opt_single_name
 			ON relation_expr access_method_clause '(' index_params ')'
-			opt_include opt_unique_null_treatment opt_reloptions OptTableSpace where_clause
+			opt_include opt_unique_null_treatment opt_reloptions OptTableSpace where_clause opt_index_visibility
 				{
 					IndexStmt *n = makeNode(IndexStmt);
 
@@ -8200,6 +8234,7 @@ IndexStmt:	CREATE opt_unique INDEX opt_concurrently opt_single_name
 					n->options = $14;
 					n->tableSpace = $15;
 					n->whereClause = $16;
+					n->isvisible = $17;
 					n->excludeOpNames = NIL;
 					n->idxcomment = NULL;
 					n->indexOid = InvalidOid;
@@ -8217,7 +8252,7 @@ IndexStmt:	CREATE opt_unique INDEX opt_concurrently opt_single_name
 				}
 			| CREATE opt_unique INDEX opt_concurrently IF_P NOT EXISTS name
 			ON relation_expr access_method_clause '(' index_params ')'
-			opt_include opt_unique_null_treatment opt_reloptions OptTableSpace where_clause
+			opt_include opt_unique_null_treatment opt_reloptions OptTableSpace where_clause opt_index_visibility
 				{
 					IndexStmt *n = makeNode(IndexStmt);
 
@@ -8232,6 +8267,7 @@ IndexStmt:	CREATE opt_unique INDEX opt_concurrently opt_single_name
 					n->options = $17;
 					n->tableSpace = $18;
 					n->whereClause = $19;
+					n->isvisible = $20;
 					n->excludeOpNames = NIL;
 					n->idxcomment = NULL;
 					n->indexOid = InvalidOid;
@@ -8254,6 +8290,12 @@ opt_unique:
 			| /*EMPTY*/								{ $$ = false; }
 		;
 
+opt_index_visibility:
+			VISIBLE                       { $$ = true; }
+			| INVISIBLE                   { $$ = false; }
+			| /*EMPTY*/                   { $$ = true; }
+		;
+
 access_method_clause:
 			USING name								{ $$ = $2; }
 			| /*EMPTY*/								{ $$ = DEFAULT_INDEX_TYPE; }
@@ -17831,6 +17873,7 @@ unreserved_keyword:
 			| INSENSITIVE
 			| INSERT
 			| INSTEAD
+			| INVISIBLE
 			| INVOKER
 			| ISOLATION
 			| KEEP
@@ -18016,6 +18059,7 @@ unreserved_keyword:
 			| VIEW
 			| VIEWS
 			| VIRTUAL
+			| VISIBLE
 			| VOLATILE
 			| WHITESPACE_P
 			| WITHIN
@@ -18425,6 +18469,7 @@ bare_label_keyword:
 			| INT_P
 			| INTEGER
 			| INTERVAL
+			| INVISIBLE
 			| INVOKER
 			| IS
 			| ISOLATION
@@ -18672,6 +18717,7 @@ bare_label_keyword:
 			| VIEW
 			| VIEWS
 			| VIRTUAL
+			| VISIBLE
 			| VOLATILE
 			| WHEN
 			| WHITESPACE_P
diff --git a/src/backend/parser/parse_utilcmd.c b/src/backend/parser/parse_utilcmd.c
index 9c1541e1fe..24a86aae09 100644
--- a/src/backend/parser/parse_utilcmd.c
+++ b/src/backend/parser/parse_utilcmd.c
@@ -1745,6 +1745,7 @@ generateClonedIndexStmt(RangeVar *heapRel, Relation source_idx,
 	index->concurrent = false;
 	index->if_not_exists = false;
 	index->reset_default_tblspc = false;
+	index->isvisible = idxrec->indisvisible;
 
 	/*
 	 * We don't try to preserve the name of the source index; instead, just
@@ -2366,6 +2367,8 @@ transformIndexConstraint(Constraint *constraint, CreateStmtContext *cxt)
 	index->concurrent = false;
 	index->if_not_exists = false;
 	index->reset_default_tblspc = constraint->reset_default_tblspc;
+	/* Ensure indexes for constraints are created as visible by default */
+	index->isvisible = true;
 
 	/*
 	 * If it's ALTER TABLE ADD CONSTRAINT USING INDEX, look up the index and
diff --git a/src/backend/utils/adt/ruleutils.c b/src/backend/utils/adt/ruleutils.c
index 9e90acedb9..199781c1ab 100644
--- a/src/backend/utils/adt/ruleutils.c
+++ b/src/backend/utils/adt/ruleutils.c
@@ -1565,6 +1565,10 @@ pg_get_indexdef_worker(Oid indexrelid, int colno,
 			else
 				appendStringInfo(&buf, " WHERE %s", str);
 		}
+
+		/* Add INVISIBLE clause if the index is invisible */
+		if (!idxrec->indisvisible)
+			appendStringInfoString(&buf, " INVISIBLE");
 	}
 
 	/* Clean up */
diff --git a/src/backend/utils/cache/relcache.c b/src/backend/utils/cache/relcache.c
index 9f54a9e72b..e4f11e6a7d 100644
--- a/src/backend/utils/cache/relcache.c
+++ b/src/backend/utils/cache/relcache.c
@@ -2318,6 +2318,7 @@ RelationReloadIndexInfo(Relation relation)
 		relation->rd_index->indisready = index->indisready;
 		relation->rd_index->indislive = index->indislive;
 		relation->rd_index->indisreplident = index->indisreplident;
+		relation->rd_index->indisvisible = index->indisvisible;
 
 		/* Copy xmin too, as that is needed to make sense of indcheckxmin */
 		HeapTupleHeaderSetXmin(relation->rd_indextuple->t_data,
diff --git a/src/backend/utils/misc/guc_tables.c b/src/backend/utils/misc/guc_tables.c
index 4eaeca89f2..fa5370089d 100644
--- a/src/backend/utils/misc/guc_tables.c
+++ b/src/backend/utils/misc/guc_tables.c
@@ -2130,6 +2130,16 @@ struct config_bool ConfigureNamesBool[] =
 		true,
 		NULL, NULL, NULL
 	},
+	{
+		{"use_invisible_index", PGC_USERSET, QUERY_TUNING_OTHER,
+			gettext_noop("Forces the planner to consider invisible indexes."),
+			NULL,
+			GUC_EXPLAIN
+		},
+		&use_invisible_index,
+		false,
+		NULL, assign_use_invisible_index, NULL
+	},
 
 	/* End-of-list marker */
 	{
diff --git a/src/backend/utils/misc/postgresql.conf.sample b/src/backend/utils/misc/postgresql.conf.sample
index ff56a1f073..aa102ceffb 100644
--- a/src/backend/utils/misc/postgresql.conf.sample
+++ b/src/backend/utils/misc/postgresql.conf.sample
@@ -427,6 +427,7 @@
 #enable_tidscan = on
 #enable_group_by_reordering = on
 #enable_distinct_reordering = on
+#use_invisible_index = off		# forces planner to consider invisible indexes
 
 # - Planner Cost Constants -
 
diff --git a/src/bin/pg_dump/pg_dump.c b/src/bin/pg_dump/pg_dump.c
index 4ca34be230..45c8de034c 100644
--- a/src/bin/pg_dump/pg_dump.c
+++ b/src/bin/pg_dump/pg_dump.c
@@ -7642,7 +7642,8 @@ getIndexes(Archive *fout, TableInfo tblinfo[], int numTables)
 				i_tablespace,
 				i_indreloptions,
 				i_indstatcols,
-				i_indstatvals;
+				i_indstatvals,
+				i_indisvisible;
 
 	/*
 	 * We want to perform just one query against pg_index.  However, we
@@ -7685,7 +7686,7 @@ getIndexes(Archive *fout, TableInfo tblinfo[], int numTables)
 
 	appendPQExpBufferStr(query,
 						 "pg_catalog.pg_get_indexdef(i.indexrelid) AS indexdef, "
-						 "i.indkey, i.indisclustered, "
+						 "i.indkey, i.indisclustered, i.indisvisible, "
 						 "c.contype, c.conname, "
 						 "c.condeferrable, c.condeferred, "
 						 "c.tableoid AS contableoid, "
@@ -7707,6 +7708,13 @@ getIndexes(Archive *fout, TableInfo tblinfo[], int numTables)
 		appendPQExpBufferStr(query,
 							 "false AS indisreplident, ");
 
+	if (fout->remoteVersion >= 180000)
+		appendPQExpBufferStr(query,
+							 "i.indisvisible, ");
+	else
+		appendPQExpBufferStr(query,
+							 "true AS indisvisible, ");
+
 	if (fout->remoteVersion >= 110000)
 		appendPQExpBufferStr(query,
 							 "inh.inhparent AS parentidx, "
@@ -7821,6 +7829,7 @@ getIndexes(Archive *fout, TableInfo tblinfo[], int numTables)
 	i_indreloptions = PQfnumber(res, "indreloptions");
 	i_indstatcols = PQfnumber(res, "indstatcols");
 	i_indstatvals = PQfnumber(res, "indstatvals");
+	i_indisvisible = PQfnumber(res, "indisvisible");
 
 	indxinfo = (IndxInfo *) pg_malloc(ntups * sizeof(IndxInfo));
 
@@ -7911,7 +7920,7 @@ getIndexes(Archive *fout, TableInfo tblinfo[], int numTables)
 								  &indAttNames, &nindAttNames))
 					pg_fatal("could not parse %s array", "indattnames");
 			}
-
+			indxinfo[j].indisvisible = (PQgetvalue(res, j, i_indisvisible)[0] == 't');
 			relstats = getRelationStatistics(fout, &indxinfo[j].dobj, relpages,
 											 PQgetvalue(res, j, i_reltuples),
 											 relallvisible, relallfrozen, indexkind,
@@ -17923,6 +17932,12 @@ dumpConstraint(Archive *fout, const ConstraintInfo *coninfo)
 			}
 
 			appendPQExpBufferStr(q, ";\n");
+
+			if (!indxinfo->indisvisible)
+			{
+				appendPQExpBuffer(q, "ALTER INDEX %s INVISIBLE;\n",
+								  fmtQualifiedDumpable(indxinfo));
+			}
 		}
 
 		/*
diff --git a/src/bin/pg_dump/pg_dump.h b/src/bin/pg_dump/pg_dump.h
index e6f0f86a45..bf6b655780 100644
--- a/src/bin/pg_dump/pg_dump.h
+++ b/src/bin/pg_dump/pg_dump.h
@@ -427,6 +427,8 @@ typedef struct _indxInfo
 
 	/* if there is an associated constraint object, its dumpId: */
 	DumpId		indexconstraint;
+
+	bool		indisvisible;
 } IndxInfo;
 
 typedef struct _indexAttachInfo
diff --git a/src/bin/pg_dump/t/002_pg_dump.pl b/src/bin/pg_dump/t/002_pg_dump.pl
index 576326daec..d61d5c15f0 100644
--- a/src/bin/pg_dump/t/002_pg_dump.pl
+++ b/src/bin/pg_dump/t/002_pg_dump.pl
@@ -2168,6 +2168,35 @@ my %tests = (
 		like => {},
 	},
 
+	'ALTER TABLE ONLY test_table ADD CONSTRAINT ... PRIMARY KEY INVISIBLE' => {
+		create_order => 97,
+		create_sql => 'CREATE TABLE dump_test.test_table_invisible (
+					   id int PRIMARY KEY
+					  );
+					  ALTER INDEX dump_test.test_table_invisible_pkey INVISIBLE;',
+		regexp => qr/^
+			\QALTER TABLE ONLY dump_test.test_table_invisible\E\n\s+
+			\QADD CONSTRAINT test_table_invisible_pkey PRIMARY KEY (id);\E\n
+			\QALTER INDEX dump_test.test_table_invisible_pkey INVISIBLE;\E
+			/xm,
+		like => { %full_runs, %dump_test_schema_runs, section_post_data => 1 },
+		unlike => { exclude_dump_test_schema => 1, only_dump_measurement => 1 },
+	},
+
+	'CREATE INDEX ... INVISIBLE' => {
+		create_order => 98,
+		create_sql => 'CREATE TABLE dump_test.test_table_mixed_indexes (
+					   id int,
+					   value int
+					  );
+					  CREATE INDEX idx_visible ON dump_test.test_table_mixed_indexes(value);
+					  CREATE UNIQUE INDEX idx_invisible ON dump_test.test_table_mixed_indexes(value) INVISIBLE;
+					  ALTER INDEX dump_test.idx_invisible INVISIBLE;',
+		regexp => qr/CREATE UNIQUE INDEX idx_invisible ON dump_test\.test_table_mixed_indexes USING btree \(value\) INVISIBLE;/m,
+		like => { %full_runs, %dump_test_schema_runs, section_post_data => 1 },
+		unlike => { exclude_dump_test_schema => 1, only_dump_measurement => 1 },
+	},
+
 	'CREATE AGGREGATE dump_test.newavg' => {
 		create_order => 25,
 		create_sql => 'CREATE AGGREGATE dump_test.newavg (
diff --git a/src/bin/psql/describe.c b/src/bin/psql/describe.c
index bf565afcc4..569974405b 100644
--- a/src/bin/psql/describe.c
+++ b/src/bin/psql/describe.c
@@ -2325,6 +2325,11 @@ describeOneTableDetails(const char *schemaname,
 		else
 			appendPQExpBufferStr(&buf, "false AS indnullsnotdistinct,\n");
 
+		if (pset.sversion >= 180000)
+			appendPQExpBufferStr(&buf, "i.indisvisible,\n");
+		else
+			appendPQExpBufferStr(&buf, "true AS indisvisible,\n");
+
 		appendPQExpBuffer(&buf, "  a.amname, c2.relname, "
 						  "pg_catalog.pg_get_expr(i.indpred, i.indrelid, true)\n"
 						  "FROM pg_catalog.pg_index i, pg_catalog.pg_class c, pg_catalog.pg_class c2, pg_catalog.pg_am a\n"
@@ -2350,9 +2355,10 @@ describeOneTableDetails(const char *schemaname,
 			char	   *deferred = PQgetvalue(result, 0, 5);
 			char	   *indisreplident = PQgetvalue(result, 0, 6);
 			char	   *indnullsnotdistinct = PQgetvalue(result, 0, 7);
-			char	   *indamname = PQgetvalue(result, 0, 8);
-			char	   *indtable = PQgetvalue(result, 0, 9);
-			char	   *indpred = PQgetvalue(result, 0, 10);
+			char	   *indisvisible = PQgetvalue(result, 0, 8);
+			char	   *indamname = PQgetvalue(result, 0, 9);
+			char	   *indtable = PQgetvalue(result, 0, 10);
+			char	   *indpred = PQgetvalue(result, 0, 11);
 
 			if (strcmp(indisprimary, "t") == 0)
 				printfPQExpBuffer(&tmpbuf, _("primary key, "));
@@ -2389,6 +2395,9 @@ describeOneTableDetails(const char *schemaname,
 			if (strcmp(indisreplident, "t") == 0)
 				appendPQExpBufferStr(&tmpbuf, _(", replica identity"));
 
+			if (strcmp(indisvisible, "t") != 0)
+				appendPQExpBufferStr(&tmpbuf, _(", invisible"));
+
 			printTableAddFooter(&cont, tmpbuf.data);
 
 			/*
diff --git a/src/bin/psql/tab-complete.in.c b/src/bin/psql/tab-complete.in.c
index 98951aef82..e2f1c8dd91 100644
--- a/src/bin/psql/tab-complete.in.c
+++ b/src/bin/psql/tab-complete.in.c
@@ -2419,7 +2419,8 @@ match_previous_words(int pattern_id,
 	else if (Matches("ALTER", "INDEX", MatchAny))
 		COMPLETE_WITH("ALTER COLUMN", "OWNER TO", "RENAME TO", "SET",
 					  "RESET", "ATTACH PARTITION",
-					  "DEPENDS ON EXTENSION", "NO DEPENDS ON EXTENSION");
+					  "DEPENDS ON EXTENSION", "NO DEPENDS ON EXTENSION",
+					  "INVISIBLE", "VISIBLE");
 	else if (Matches("ALTER", "INDEX", MatchAny, "ATTACH"))
 		COMPLETE_WITH("PARTITION");
 	else if (Matches("ALTER", "INDEX", MatchAny, "ATTACH", "PARTITION"))
diff --git a/src/include/catalog/index.h b/src/include/catalog/index.h
index 4daa8bef5e..75bef5bd88 100644
--- a/src/include/catalog/index.h
+++ b/src/include/catalog/index.h
@@ -65,6 +65,7 @@ extern void index_check_primary_key(Relation heapRel,
 #define	INDEX_CREATE_IF_NOT_EXISTS			(1 << 4)
 #define	INDEX_CREATE_PARTITIONED			(1 << 5)
 #define INDEX_CREATE_INVALID				(1 << 6)
+#define INDEX_CREATE_VISIBLE				(1 << 7)
 
 extern Oid	index_create(Relation heapRelation,
 						 const char *indexRelationName,
@@ -175,7 +176,6 @@ extern void RestoreReindexState(const void *reindexstate);
 
 extern void IndexSetParentIndex(Relation partitionIdx, Oid parentOid);
 
-
 /*
  * itemptr_encode - Encode ItemPointer as int64/int8
  *
diff --git a/src/include/catalog/pg_index.h b/src/include/catalog/pg_index.h
index 4392b9d221..ec8e5dc4bf 100644
--- a/src/include/catalog/pg_index.h
+++ b/src/include/catalog/pg_index.h
@@ -44,6 +44,8 @@ CATALOG(pg_index,2610,IndexRelationId) BKI_SCHEMA_MACRO
 	bool		indisready;		/* is this index ready for inserts? */
 	bool		indislive;		/* is this index alive at all? */
 	bool		indisreplident; /* is this index the identity for replication? */
+	bool		indisvisible BKI_DEFAULT(t);	/* is this index visible for
+												 * use by queries? */
 
 	/* variable-length fields start here, but we allow direct access to indkey */
 	int2vector	indkey BKI_FORCE_NOT_NULL;	/* column numbers of indexed cols,
diff --git a/src/include/nodes/parsenodes.h b/src/include/nodes/parsenodes.h
index df331b1c0d..0185160771 100644
--- a/src/include/nodes/parsenodes.h
+++ b/src/include/nodes/parsenodes.h
@@ -2472,6 +2472,8 @@ typedef enum AlterTableType
 	AT_SetIdentity,				/* SET identity column options */
 	AT_DropIdentity,			/* DROP IDENTITY */
 	AT_ReAddStatistics,			/* internal to commands/tablecmds.c */
+	AT_SetIndexVisible,			/* Set INDEX visible */
+	AT_SetIndexInvisible,		/* Set INDEX invisible */
 } AlterTableType;
 
 typedef struct AlterTableCmd	/* one subcommand of an ALTER TABLE */
@@ -3468,6 +3470,8 @@ typedef struct IndexStmt
 	bool		if_not_exists;	/* just do nothing if index already exists? */
 	bool		reset_default_tblspc;	/* reset default_tablespace prior to
 										 * executing */
+	bool		isvisible;		/* true if VISIBLE (default), false if
+								 * INVISIBLE */
 } IndexStmt;
 
 /* ----------------------
diff --git a/src/include/optimizer/optimizer.h b/src/include/optimizer/optimizer.h
index 78e05d88c8..df7abcb20a 100644
--- a/src/include/optimizer/optimizer.h
+++ b/src/include/optimizer/optimizer.h
@@ -207,4 +207,9 @@ extern List *pull_var_clause(Node *node, int flags);
 extern Node *flatten_join_alias_vars(PlannerInfo *root, Query *query, Node *node);
 extern Node *flatten_group_exprs(PlannerInfo *root, Query *query, Node *node);
 
+/*
+ * GUC to tell planner to consider invisible indexes.
+ */
+extern bool use_invisible_index;
+
 #endif							/* OPTIMIZER_H */
diff --git a/src/include/parser/kwlist.h b/src/include/parser/kwlist.h
index 40cf090ce6..7f0947988b 100644
--- a/src/include/parser/kwlist.h
+++ b/src/include/parser/kwlist.h
@@ -229,6 +229,7 @@ PG_KEYWORD("integer", INTEGER, COL_NAME_KEYWORD, BARE_LABEL)
 PG_KEYWORD("intersect", INTERSECT, RESERVED_KEYWORD, AS_LABEL)
 PG_KEYWORD("interval", INTERVAL, COL_NAME_KEYWORD, BARE_LABEL)
 PG_KEYWORD("into", INTO, RESERVED_KEYWORD, AS_LABEL)
+PG_KEYWORD("invisible", INVISIBLE, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("invoker", INVOKER, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("is", IS, TYPE_FUNC_NAME_KEYWORD, BARE_LABEL)
 PG_KEYWORD("isnull", ISNULL, TYPE_FUNC_NAME_KEYWORD, AS_LABEL)
@@ -492,6 +493,7 @@ PG_KEYWORD("version", VERSION_P, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("view", VIEW, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("views", VIEWS, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("virtual", VIRTUAL, UNRESERVED_KEYWORD, BARE_LABEL)
+PG_KEYWORD("visible", VISIBLE, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("volatile", VOLATILE, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("when", WHEN, RESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("where", WHERE, RESERVED_KEYWORD, AS_LABEL)
diff --git a/src/include/utils/guc_hooks.h b/src/include/utils/guc_hooks.h
index 799fa7ace6..dd5128fd87 100644
--- a/src/include/utils/guc_hooks.h
+++ b/src/include/utils/guc_hooks.h
@@ -178,5 +178,6 @@ extern bool check_synchronized_standby_slots(char **newval, void **extra,
 extern void assign_synchronized_standby_slots(const char *newval, void *extra);
 extern bool check_idle_replication_slot_timeout(int *newval, void **extra,
 												GucSource source);
+extern void assign_use_invisible_index(bool newval, void *extra);
 
 #endif							/* GUC_HOOKS_H */
diff --git a/src/test/modules/test_ddl_deparse/Makefile b/src/test/modules/test_ddl_deparse/Makefile
index 3a57a95c84..747d8b5835 100644
--- a/src/test/modules/test_ddl_deparse/Makefile
+++ b/src/test/modules/test_ddl_deparse/Makefile
@@ -27,7 +27,8 @@ REGRESS = test_ddl_deparse \
 	alter_type_enum \
 	opfamily \
 	defprivs \
-	matviews
+	matviews \
+	alter_index
 
 EXTRA_INSTALL = contrib/pg_stat_statements
 
diff --git a/src/test/modules/test_ddl_deparse/expected/alter_index.out b/src/test/modules/test_ddl_deparse/expected/alter_index.out
new file mode 100644
index 0000000000..f502baf1c5
--- /dev/null
+++ b/src/test/modules/test_ddl_deparse/expected/alter_index.out
@@ -0,0 +1,29 @@
+-- Test index visibility commands
+CREATE TABLE visibility_test (id int);
+NOTICE:  DDL test: type simple, tag CREATE TABLE
+CREATE INDEX idx_vis ON visibility_test(id);
+NOTICE:  DDL test: type simple, tag CREATE INDEX
+ALTER INDEX idx_vis INVISIBLE;
+NOTICE:  DDL test: type alter table, tag ALTER INDEX
+NOTICE:    subcommand: type SET INVISIBLE desc <NULL>
+ALTER INDEX idx_vis VISIBLE;
+NOTICE:  DDL test: type alter table, tag ALTER INDEX
+NOTICE:    subcommand: type SET VISIBLE desc <NULL>
+ALTER INDEX idx_vis INVISIBLE;
+NOTICE:  DDL test: type alter table, tag ALTER INDEX
+NOTICE:    subcommand: type SET INVISIBLE desc <NULL>
+REINDEX INDEX idx_vis;
+NOTICE:  DDL test: type simple, tag REINDEX
+CREATE SCHEMA visibility_schema;
+NOTICE:  DDL test: type simple, tag CREATE SCHEMA
+CREATE TABLE visibility_schema.test2 (id int);
+NOTICE:  DDL test: type simple, tag CREATE TABLE
+CREATE INDEX idx_vis2 ON visibility_schema.test2(id);
+NOTICE:  DDL test: type simple, tag CREATE INDEX
+ALTER INDEX visibility_schema.idx_vis2 INVISIBLE;
+NOTICE:  DDL test: type alter table, tag ALTER INDEX
+NOTICE:    subcommand: type SET INVISIBLE desc <NULL>
+-- Clean up
+DROP SCHEMA visibility_schema CASCADE;
+NOTICE:  drop cascades to table visibility_schema.test2
+DROP TABLE visibility_test CASCADE;
diff --git a/src/test/modules/test_ddl_deparse/meson.build b/src/test/modules/test_ddl_deparse/meson.build
index bff65ba633..6654b5e46d 100644
--- a/src/test/modules/test_ddl_deparse/meson.build
+++ b/src/test/modules/test_ddl_deparse/meson.build
@@ -48,6 +48,7 @@ tests += {
       'opfamily',
       'defprivs',
       'matviews',
+      'alter_index',
     ],
   },
 }
diff --git a/src/test/modules/test_ddl_deparse/sql/alter_index.sql b/src/test/modules/test_ddl_deparse/sql/alter_index.sql
new file mode 100644
index 0000000000..7a34dc6692
--- /dev/null
+++ b/src/test/modules/test_ddl_deparse/sql/alter_index.sql
@@ -0,0 +1,18 @@
+-- Test index visibility commands
+CREATE TABLE visibility_test (id int);
+CREATE INDEX idx_vis ON visibility_test(id);
+
+ALTER INDEX idx_vis INVISIBLE;
+ALTER INDEX idx_vis VISIBLE;
+
+ALTER INDEX idx_vis INVISIBLE;
+REINDEX INDEX idx_vis;
+
+CREATE SCHEMA visibility_schema;
+CREATE TABLE visibility_schema.test2 (id int);
+CREATE INDEX idx_vis2 ON visibility_schema.test2(id);
+ALTER INDEX visibility_schema.idx_vis2 INVISIBLE;
+
+-- Clean up
+DROP SCHEMA visibility_schema CASCADE;
+DROP TABLE visibility_test CASCADE;
diff --git a/src/test/modules/test_ddl_deparse/test_ddl_deparse.c b/src/test/modules/test_ddl_deparse/test_ddl_deparse.c
index 193669f2bc..8d7c7e5894 100644
--- a/src/test/modules/test_ddl_deparse/test_ddl_deparse.c
+++ b/src/test/modules/test_ddl_deparse/test_ddl_deparse.c
@@ -308,6 +308,12 @@ get_altertable_subcmdinfo(PG_FUNCTION_ARGS)
 			case AT_ReAddStatistics:
 				strtype = "(re) ADD STATS";
 				break;
+			case AT_SetIndexVisible:
+				strtype = "SET VISIBLE";
+				break;
+			case AT_SetIndexInvisible:
+				strtype = "SET INVISIBLE";
+				break;
 		}
 
 		if (subcmd->recurse)
diff --git a/src/test/regress/expected/create_index.out b/src/test/regress/expected/create_index.out
index 15be0043ad..65c3ecf05c 100644
--- a/src/test/regress/expected/create_index.out
+++ b/src/test/regress/expected/create_index.out
@@ -3394,6 +3394,801 @@ ERROR:  REINDEX SCHEMA cannot run inside a transaction block
 END;
 -- concurrently
 REINDEX SCHEMA CONCURRENTLY schema_to_reindex;
+-- Test index visibility functionality
+CREATE TABLE index_test(
+    id INT PRIMARY KEY,
+    data TEXT,
+    num INT,
+    vector INT[],
+    range INT4RANGE
+);
+INSERT INTO index_test
+SELECT
+    g,
+    'data ' || g,
+    g % 100,
+    ARRAY[g, g+1, g+2],
+    int4range(g, g+10)
+FROM generate_series(1, 1000) g;
+-- Function for testing
+CREATE FUNCTION get_data_length(text) RETURNS INT AS $$
+    SELECT length($1);
+$$ LANGUAGE SQL IMMUTABLE;
+-- Helper function to show index status
+CREATE OR REPLACE FUNCTION show_index_status(index_name text)
+RETURNS TABLE (
+    indexrelid regclass,
+    indisvalid boolean,
+    indisready boolean,
+    indislive boolean,
+    indisvisible boolean
+) AS $$
+BEGIN
+    RETURN QUERY EXECUTE format('
+        SELECT indexrelid::regclass, indisvalid, indisready, indislive, indisvisible
+        FROM pg_index
+        WHERE indexrelid = %L::regclass', index_name);
+END;
+$$ LANGUAGE plpgsql;
+-- Create and test each index type
+-- 1. Basic single-column index
+CREATE INDEX idx_single ON index_test(data);
+SELECT show_index_status('idx_single');
+  show_index_status   
+----------------------
+ (idx_single,t,t,t,t)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE data = 'data 500';
+                  QUERY PLAN                   
+-----------------------------------------------
+ Bitmap Heap Scan on index_test
+   Recheck Cond: (data = 'data 500'::text)
+   ->  Bitmap Index Scan on idx_single
+         Index Cond: (data = 'data 500'::text)
+(4 rows)
+
+ALTER INDEX idx_single INVISIBLE;
+SELECT show_index_status('idx_single');
+  show_index_status   
+----------------------
+ (idx_single,t,t,t,f)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE data = 'data 500';
+             QUERY PLAN              
+-------------------------------------
+ Seq Scan on index_test
+   Filter: (data = 'data 500'::text)
+(2 rows)
+
+ALTER INDEX idx_single VISIBLE;
+SELECT show_index_status('idx_single');
+  show_index_status   
+----------------------
+ (idx_single,t,t,t,t)
+(1 row)
+
+-- 2. Multi-column index
+CREATE INDEX idx_multi ON index_test(num, data);
+SELECT show_index_status('idx_multi');
+  show_index_status  
+---------------------
+ (idx_multi,t,t,t,t)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE num = 50 AND data > 'data 500';
+                           QUERY PLAN                           
+----------------------------------------------------------------
+ Bitmap Heap Scan on index_test
+   Recheck Cond: ((num = 50) AND (data > 'data 500'::text))
+   ->  Bitmap Index Scan on idx_multi
+         Index Cond: ((num = 50) AND (data > 'data 500'::text))
+(4 rows)
+
+ALTER INDEX idx_multi INVISIBLE;
+SELECT show_index_status('idx_multi');
+  show_index_status  
+---------------------
+ (idx_multi,t,t,t,f)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE num = 50 AND data > 'data 500';
+                      QUERY PLAN                      
+------------------------------------------------------
+ Seq Scan on index_test
+   Filter: ((data > 'data 500'::text) AND (num = 50))
+(2 rows)
+
+ALTER INDEX idx_multi VISIBLE;
+SELECT show_index_status('idx_multi');
+  show_index_status  
+---------------------
+ (idx_multi,t,t,t,t)
+(1 row)
+
+-- 3. Partial index
+CREATE INDEX idx_partial ON index_test(num) WHERE num < 50;
+SELECT show_index_status('idx_partial');
+   show_index_status   
+-----------------------
+ (idx_partial,t,t,t,t)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE num = 25;
+               QUERY PLAN               
+----------------------------------------
+ Bitmap Heap Scan on index_test
+   Recheck Cond: (num = 25)
+   ->  Bitmap Index Scan on idx_partial
+         Index Cond: (num = 25)
+(4 rows)
+
+ALTER INDEX idx_partial INVISIBLE;
+SELECT show_index_status('idx_partial');
+   show_index_status   
+-----------------------
+ (idx_partial,t,t,t,f)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE num = 25;
+              QUERY PLAN              
+--------------------------------------
+ Bitmap Heap Scan on index_test
+   Recheck Cond: (num = 25)
+   ->  Bitmap Index Scan on idx_multi
+         Index Cond: (num = 25)
+(4 rows)
+
+ALTER INDEX idx_partial VISIBLE;
+SELECT show_index_status('idx_partial');
+   show_index_status   
+-----------------------
+ (idx_partial,t,t,t,t)
+(1 row)
+
+-- 4. Expression index
+CREATE INDEX idx_expression ON index_test((lower(data)));
+SELECT show_index_status('idx_expression');
+    show_index_status     
+--------------------------
+ (idx_expression,t,t,t,t)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE lower(data) = 'data 500';
+                      QUERY PLAN                      
+------------------------------------------------------
+ Bitmap Heap Scan on index_test
+   Recheck Cond: (lower(data) = 'data 500'::text)
+   ->  Bitmap Index Scan on idx_expression
+         Index Cond: (lower(data) = 'data 500'::text)
+(4 rows)
+
+ALTER INDEX idx_expression INVISIBLE;
+SELECT show_index_status('idx_expression');
+    show_index_status     
+--------------------------
+ (idx_expression,t,t,t,f)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE lower(data) = 'data 500';
+                 QUERY PLAN                 
+--------------------------------------------
+ Seq Scan on index_test
+   Filter: (lower(data) = 'data 500'::text)
+(2 rows)
+
+ALTER INDEX idx_expression VISIBLE;
+SELECT show_index_status('idx_expression');
+    show_index_status     
+--------------------------
+ (idx_expression,t,t,t,t)
+(1 row)
+
+-- 5. GIN index
+CREATE INDEX idx_gin ON index_test USING gin(vector);
+SELECT show_index_status('idx_gin');
+ show_index_status 
+-------------------
+ (idx_gin,t,t,t,t)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE vector @> ARRAY[500];
+                     QUERY PLAN                     
+----------------------------------------------------
+ Bitmap Heap Scan on index_test
+   Recheck Cond: (vector @> '{500}'::integer[])
+   ->  Bitmap Index Scan on idx_gin
+         Index Cond: (vector @> '{500}'::integer[])
+(4 rows)
+
+ALTER INDEX idx_gin INVISIBLE;
+SELECT show_index_status('idx_gin');
+ show_index_status 
+-------------------
+ (idx_gin,t,t,t,f)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE vector @> ARRAY[500];
+                QUERY PLAN                
+------------------------------------------
+ Seq Scan on index_test
+   Filter: (vector @> '{500}'::integer[])
+(2 rows)
+
+ALTER INDEX idx_gin VISIBLE;
+SELECT show_index_status('idx_gin');
+ show_index_status 
+-------------------
+ (idx_gin,t,t,t,t)
+(1 row)
+
+-- 6. GiST index
+CREATE INDEX idx_gist ON index_test USING gist(range);
+SELECT show_index_status('idx_gist');
+ show_index_status  
+--------------------
+ (idx_gist,t,t,t,t)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE range && int4range(100, 110);
+                      QUERY PLAN                       
+-------------------------------------------------------
+ Bitmap Heap Scan on index_test
+   Recheck Cond: (range && '[100,110)'::int4range)
+   ->  Bitmap Index Scan on idx_gist
+         Index Cond: (range && '[100,110)'::int4range)
+(4 rows)
+
+ALTER INDEX idx_gist INVISIBLE;
+SELECT show_index_status('idx_gist');
+ show_index_status  
+--------------------
+ (idx_gist,t,t,t,f)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE range && int4range(100, 110);
+                 QUERY PLAN                  
+---------------------------------------------
+ Seq Scan on index_test
+   Filter: (range && '[100,110)'::int4range)
+(2 rows)
+
+ALTER INDEX idx_gist VISIBLE;
+SELECT show_index_status('idx_gist');
+ show_index_status  
+--------------------
+ (idx_gist,t,t,t,t)
+(1 row)
+
+-- 7. Covering index
+CREATE INDEX idx_covering ON index_test(num) INCLUDE (data);
+SELECT show_index_status('idx_covering');
+   show_index_status    
+------------------------
+ (idx_covering,t,t,t,t)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT num, data FROM index_test WHERE num = 50;
+               QUERY PLAN                
+-----------------------------------------
+ Bitmap Heap Scan on index_test
+   Recheck Cond: (num = 50)
+   ->  Bitmap Index Scan on idx_covering
+         Index Cond: (num = 50)
+(4 rows)
+
+ALTER INDEX idx_covering INVISIBLE;
+SELECT show_index_status('idx_covering');
+   show_index_status    
+------------------------
+ (idx_covering,t,t,t,f)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT num, data FROM index_test WHERE num = 50;
+              QUERY PLAN              
+--------------------------------------
+ Bitmap Heap Scan on index_test
+   Recheck Cond: (num = 50)
+   ->  Bitmap Index Scan on idx_multi
+         Index Cond: (num = 50)
+(4 rows)
+
+ALTER INDEX idx_covering VISIBLE;
+SELECT show_index_status('idx_covering');
+   show_index_status    
+------------------------
+ (idx_covering,t,t,t,t)
+(1 row)
+
+-- 8. Unique index
+CREATE UNIQUE INDEX idx_unique ON index_test(id, data);
+SELECT show_index_status('idx_unique');
+  show_index_status   
+----------------------
+ (idx_unique,t,t,t,t)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE id = 500 AND data = 'data 500';
+                        QUERY PLAN                        
+----------------------------------------------------------
+ Index Scan using idx_unique on index_test
+   Index Cond: ((id = 500) AND (data = 'data 500'::text))
+(2 rows)
+
+ALTER INDEX idx_unique INVISIBLE;
+SELECT show_index_status('idx_unique');
+  show_index_status   
+----------------------
+ (idx_unique,t,t,t,f)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE id = 500 AND data = 'data 500';
+                   QUERY PLAN                   
+------------------------------------------------
+ Index Scan using index_test_pkey on index_test
+   Index Cond: (id = 500)
+   Filter: (data = 'data 500'::text)
+(3 rows)
+
+ALTER INDEX idx_unique VISIBLE;
+SELECT show_index_status('idx_unique');
+  show_index_status   
+----------------------
+ (idx_unique,t,t,t,t)
+(1 row)
+
+-- 9. Function-based index
+CREATE INDEX idx_func ON index_test(get_data_length(data));
+SELECT show_index_status('idx_func');
+ show_index_status  
+--------------------
+ (idx_func,t,t,t,t)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE get_data_length(data) = 10;
+               QUERY PLAN                
+-----------------------------------------
+ Bitmap Heap Scan on index_test
+   Recheck Cond: (length(data) = 10)
+   ->  Bitmap Index Scan on idx_func
+         Index Cond: (length(data) = 10)
+(4 rows)
+
+ALTER INDEX idx_func INVISIBLE;
+SELECT show_index_status('idx_func');
+ show_index_status  
+--------------------
+ (idx_func,t,t,t,f)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE get_data_length(data) = 10;
+          QUERY PLAN           
+-------------------------------
+ Seq Scan on index_test
+   Filter: (length(data) = 10)
+(2 rows)
+
+ALTER INDEX idx_func VISIBLE;
+SELECT show_index_status('idx_func');
+ show_index_status  
+--------------------
+ (idx_func,t,t,t,t)
+(1 row)
+
+-- 10. Join index
+CREATE TABLE join_test (id INT PRIMARY KEY, ref_id INT);
+INSERT INTO join_test SELECT g, g % 100 FROM generate_series(1, 1000) g;
+CREATE INDEX idx_join ON join_test(ref_id);
+SELECT show_index_status('idx_join');
+ show_index_status  
+--------------------
+ (idx_join,t,t,t,t)
+(1 row)
+
+EXPLAIN (COSTS OFF)
+SELECT jt.id, it.data
+FROM join_test jt
+JOIN index_test it ON jt.ref_id = it.num
+WHERE jt.id BETWEEN 100 AND 200;
+                          QUERY PLAN                           
+---------------------------------------------------------------
+ Hash Join
+   Hash Cond: (it.num = jt.ref_id)
+   ->  Seq Scan on index_test it
+   ->  Hash
+         ->  Bitmap Heap Scan on join_test jt
+               Recheck Cond: ((id >= 100) AND (id <= 200))
+               ->  Bitmap Index Scan on join_test_pkey
+                     Index Cond: ((id >= 100) AND (id <= 200))
+(8 rows)
+
+-- Set all indexes to invisible to force seq scan
+ALTER INDEX idx_join INVISIBLE;
+ALTER INDEX join_test_pkey INVISIBLE;
+SELECT show_index_status('idx_join');
+ show_index_status  
+--------------------
+ (idx_join,t,t,t,f)
+(1 row)
+
+SELECT show_index_status('join_test_pkey');
+    show_index_status     
+--------------------------
+ (join_test_pkey,t,t,t,f)
+(1 row)
+
+EXPLAIN (COSTS OFF)
+SELECT jt.id, it.data
+FROM join_test jt
+JOIN index_test it ON jt.ref_id = it.num
+WHERE jt.id BETWEEN 100 AND 200;
+                     QUERY PLAN                      
+-----------------------------------------------------
+ Hash Join
+   Hash Cond: (it.num = jt.ref_id)
+   ->  Seq Scan on index_test it
+   ->  Hash
+         ->  Seq Scan on join_test jt
+               Filter: ((id >= 100) AND (id <= 200))
+(6 rows)
+
+ALTER INDEX idx_join VISIBLE;
+ALTER INDEX join_test_pkey VISIBLE;
+SELECT show_index_status('idx_join');
+ show_index_status  
+--------------------
+ (idx_join,t,t,t,t)
+(1 row)
+
+SELECT show_index_status('join_test_pkey');
+    show_index_status     
+--------------------------
+ (join_test_pkey,t,t,t,t)
+(1 row)
+
+-- Test REINDEX CONCURRENTLY
+REINDEX INDEX CONCURRENTLY idx_join;
+SELECT show_index_status('idx_join');
+ show_index_status  
+--------------------
+ (idx_join,t,t,t,t)
+(1 row)
+
+ALTER INDEX idx_join INVISIBLE;
+SELECT show_index_status('idx_join');
+ show_index_status  
+--------------------
+ (idx_join,t,t,t,f)
+(1 row)
+
+REINDEX INDEX CONCURRENTLY idx_join;
+SELECT show_index_status('idx_join');
+ show_index_status  
+--------------------
+ (idx_join,t,t,t,f)
+(1 row)
+
+SELECT pg_get_indexdef('idx_join'::regclass);
+                                   pg_get_indexdef                                   
+-------------------------------------------------------------------------------------
+ CREATE INDEX idx_join ON schema_to_reindex.join_test USING btree (ref_id) INVISIBLE
+(1 row)
+
+ALTER INDEX idx_join VISIBLE;
+SELECT pg_get_indexdef('idx_join'::regclass);
+                              pg_get_indexdef                              
+---------------------------------------------------------------------------
+ CREATE INDEX idx_join ON schema_to_reindex.join_test USING btree (ref_id)
+(1 row)
+
+-- Test index visibility with indcheckxmin being true
+CREATE TABLE indcheckxmin_test(id int PRIMARY KEY);
+INSERT INTO indcheckxmin_test VALUES (1), (2), (3);
+CREATE INDEX CONCURRENTLY idx_checkxmin ON indcheckxmin_test(id);
+BEGIN;
+-- Simulate indcheckxmin being true
+UPDATE pg_index SET indcheckxmin = true WHERE indexrelid = 'idx_checkxmin'::regclass;
+ALTER INDEX idx_checkxmin INVISIBLE;  -- expect fail
+ERROR:  cannot update index visibility while indcheckxmin is true
+HINT:  Wait for all transactions that might see inconsistent HOT chains to complete
+ROLLBACK;
+-- Test prepared statements with index visibility
+CREATE TABLE prep_idx_test (id int, data text);
+CREATE INDEX prep_idx1 ON prep_idx_test(data);
+INSERT INTO prep_idx_test SELECT g, 'data ' || g FROM generate_series(1,100) g;
+-- Test with visible index
+PREPARE idx_plan AS SELECT * FROM prep_idx_test WHERE data = $1;
+EXPLAIN (COSTS OFF) EXECUTE idx_plan('data 1');
+                 QUERY PLAN                  
+---------------------------------------------
+ Bitmap Heap Scan on prep_idx_test
+   Recheck Cond: (data = 'data 1'::text)
+   ->  Bitmap Index Scan on prep_idx1
+         Index Cond: (data = 'data 1'::text)
+(4 rows)
+
+EXECUTE idx_plan('data 1');
+ id |  data  
+----+--------
+  1 | data 1
+(1 row)
+
+-- Test with invisible index
+ALTER INDEX prep_idx1 INVISIBLE;
+EXPLAIN (COSTS OFF) EXECUTE idx_plan('data 1');
+            QUERY PLAN             
+-----------------------------------
+ Seq Scan on prep_idx_test
+   Filter: (data = 'data 1'::text)
+(2 rows)
+
+EXECUTE idx_plan('data 1');
+ id |  data  
+----+--------
+  1 | data 1
+(1 row)
+
+-- Test with use_invisible_index
+SET use_invisible_index TO on;
+EXPLAIN (COSTS OFF) EXECUTE idx_plan('data 1');
+                 QUERY PLAN                  
+---------------------------------------------
+ Bitmap Heap Scan on prep_idx_test
+   Recheck Cond: (data = 'data 1'::text)
+   ->  Bitmap Index Scan on prep_idx1
+         Index Cond: (data = 'data 1'::text)
+(4 rows)
+
+EXECUTE idx_plan('data 1');
+ id |  data  
+----+--------
+  1 | data 1
+(1 row)
+
+SET use_invisible_index TO off;
+-- Assert plan cache is reset and index is not used
+EXPLAIN (COSTS OFF) EXECUTE idx_plan('data 1');
+            QUERY PLAN             
+-----------------------------------
+ Seq Scan on prep_idx_test
+   Filter: (data = 'data 1'::text)
+(2 rows)
+
+-- Make index visible and test again
+ALTER INDEX prep_idx1 VISIBLE;
+EXPLAIN (COSTS OFF) EXECUTE idx_plan('data 1');
+                 QUERY PLAN                  
+---------------------------------------------
+ Bitmap Heap Scan on prep_idx_test
+   Recheck Cond: (data = 'data 1'::text)
+   ->  Bitmap Index Scan on prep_idx1
+         Index Cond: (data = 'data 1'::text)
+(4 rows)
+
+EXECUTE idx_plan('data 1');
+ id |  data  
+----+--------
+  1 | data 1
+(1 row)
+
+-- Test index visibility with partitioned tables
+CREATE TABLE part_tbl(id int, data text) PARTITION BY RANGE(id);
+CREATE TABLE part1 PARTITION OF part_tbl FOR VALUES FROM (1) TO (100);
+CREATE TABLE part2 PARTITION OF part_tbl FOR VALUES FROM (100) TO (200);
+INSERT INTO part_tbl
+SELECT g, 'data ' || g
+FROM generate_series(1, 199) g;
+CREATE INDEX idx_part_tbl ON part_tbl(data);
+SELECT c.relname, i.indisvisible
+FROM pg_index i
+JOIN pg_class c ON i.indexrelid = c.oid
+WHERE c.relname LIKE 'idx_part_tbl%'
+ORDER BY c.relname;
+   relname    | indisvisible 
+--------------+--------------
+ idx_part_tbl | t
+(1 row)
+
+-- Force use of indexes to avoid flaky test results
+SET enable_seqscan = off;
+EXPLAIN (COSTS OFF)
+SELECT * FROM part_tbl WHERE data = 'data 50';
+                        QUERY PLAN                         
+-----------------------------------------------------------
+ Append
+   ->  Index Scan using part1_data_idx on part1 part_tbl_1
+         Index Cond: (data = 'data 50'::text)
+   ->  Index Scan using part2_data_idx on part2 part_tbl_2
+         Index Cond: (data = 'data 50'::text)
+(5 rows)
+
+ALTER INDEX idx_part_tbl INVISIBLE;
+SELECT c.relname, i.indisvisible
+FROM pg_index i
+JOIN pg_class c ON i.indexrelid = c.oid
+WHERE c.relname LIKE 'idx_part_tbl%'
+ORDER BY c.relname;
+   relname    | indisvisible 
+--------------+--------------
+ idx_part_tbl | f
+(1 row)
+
+-- Check query plan after setting invisible (should use seq scan)
+EXPLAIN (COSTS OFF)
+SELECT * FROM part_tbl WHERE data = 'data 50';
+                QUERY PLAN                
+------------------------------------------
+ Append
+   ->  Seq Scan on part1 part_tbl_1
+         Disabled: true
+         Filter: (data = 'data 50'::text)
+   ->  Seq Scan on part2 part_tbl_2
+         Disabled: true
+         Filter: (data = 'data 50'::text)
+(7 rows)
+
+SET use_invisible_index TO on;
+EXPLAIN (COSTS OFF)
+SELECT * FROM part_tbl WHERE data = 'data 50';
+                        QUERY PLAN                         
+-----------------------------------------------------------
+ Append
+   ->  Index Scan using part1_data_idx on part1 part_tbl_1
+         Index Cond: (data = 'data 50'::text)
+   ->  Index Scan using part2_data_idx on part2 part_tbl_2
+         Index Cond: (data = 'data 50'::text)
+(5 rows)
+
+SET use_invisible_index TO off;
+EXPLAIN (COSTS OFF)
+SELECT * FROM part_tbl WHERE data = 'data 50';
+                QUERY PLAN                
+------------------------------------------
+ Append
+   ->  Seq Scan on part1 part_tbl_1
+         Disabled: true
+         Filter: (data = 'data 50'::text)
+   ->  Seq Scan on part2 part_tbl_2
+         Disabled: true
+         Filter: (data = 'data 50'::text)
+(7 rows)
+
+ALTER INDEX idx_part_tbl VISIBLE;
+SELECT c.relname, i.indisvisible
+FROM pg_index i
+JOIN pg_class c ON i.indexrelid = c.oid
+WHERE c.relname LIKE 'idx_part_tbl%'
+ORDER BY c.relname;
+   relname    | indisvisible 
+--------------+--------------
+ idx_part_tbl | t
+(1 row)
+
+EXPLAIN (COSTS OFF)
+SELECT * FROM part_tbl WHERE data = 'data 50';
+                        QUERY PLAN                         
+-----------------------------------------------------------
+ Append
+   ->  Index Scan using part1_data_idx on part1 part_tbl_1
+         Index Cond: (data = 'data 50'::text)
+   ->  Index Scan using part2_data_idx on part2 part_tbl_2
+         Index Cond: (data = 'data 50'::text)
+(5 rows)
+
+SET enable_seqscan = on;
+-- Test REINDEX maintains visibility setting
+ALTER INDEX idx_part_tbl INVISIBLE;
+REINDEX INDEX idx_part_tbl;
+SELECT c.relname, i.indisvisible
+FROM pg_index i
+JOIN pg_class c ON i.indexrelid = c.oid
+WHERE c.relname LIKE 'idx_part_tbl%'
+ORDER BY c.relname;
+   relname    | indisvisible 
+--------------+--------------
+ idx_part_tbl | f
+(1 row)
+
+-- Test that index visibility is preserved after ALTER TABLE
+CREATE TABLE vis_test(id INT PRIMARY KEY, data text);
+\d vis_test
+        Table "schema_to_reindex.vis_test"
+ Column |  Type   | Collation | Nullable | Default 
+--------+---------+-----------+----------+---------
+ id     | integer |           | not null | 
+ data   | text    |           |          | 
+Indexes:
+    "vis_test_pkey" PRIMARY KEY, btree (id)
+
+ALTER INDEX vis_test_pkey INVISIBLE;
+\d vis_test
+        Table "schema_to_reindex.vis_test"
+ Column |  Type   | Collation | Nullable | Default 
+--------+---------+-----------+----------+---------
+ id     | integer |           | not null | 
+ data   | text    |           |          | 
+Indexes:
+    "vis_test_pkey" PRIMARY KEY, btree (id) INVISIBLE
+
+ALTER TABLE vis_test ALTER COLUMN id SET DATA TYPE bigint;
+\d vis_test
+        Table "schema_to_reindex.vis_test"
+ Column |  Type  | Collation | Nullable | Default 
+--------+--------+-----------+----------+---------
+ id     | bigint |           | not null | 
+ data   | text   |           |          | 
+Indexes:
+    "vis_test_pkey" PRIMARY KEY, btree (id) INVISIBLE
+
+ALTER TABLE vis_test ALTER COLUMN id SET DATA TYPE int;
+\d vis_test
+        Table "schema_to_reindex.vis_test"
+ Column |  Type   | Collation | Nullable | Default 
+--------+---------+-----------+----------+---------
+ id     | integer |           | not null | 
+ data   | text    |           |          | 
+Indexes:
+    "vis_test_pkey" PRIMARY KEY, btree (id) INVISIBLE
+
+ALTER INDEX vis_test_pkey VISIBLE;
+\d vis_test
+        Table "schema_to_reindex.vis_test"
+ Column |  Type   | Collation | Nullable | Default 
+--------+---------+-----------+----------+---------
+ id     | integer |           | not null | 
+ data   | text    |           |          | 
+Indexes:
+    "vis_test_pkey" PRIMARY KEY, btree (id)
+
+-- Test CREATE INDEX with INVISIBLE option
+CREATE TABLE invis_test(id int, data text);
+INSERT INTO invis_test SELECT g, 'data ' || g FROM generate_series(1,100) g;
+CREATE INDEX idx_invis1 ON invis_test(data) INVISIBLE;
+\d invis_test
+       Table "schema_to_reindex.invis_test"
+ Column |  Type   | Collation | Nullable | Default 
+--------+---------+-----------+----------+---------
+ id     | integer |           |          | 
+ data   | text    |           |          | 
+Indexes:
+    "idx_invis1" btree (data) INVISIBLE
+
+\d idx_invis1
+Index "schema_to_reindex.idx_invis1"
+ Column | Type | Key? | Definition 
+--------+------+------+------------
+ data   | text | yes  | data
+btree, for table "schema_to_reindex.invis_test", invisible
+
+ALTER INDEX idx_invis1 VISIBLE;
+\d invis_test
+       Table "schema_to_reindex.invis_test"
+ Column |  Type   | Collation | Nullable | Default 
+--------+---------+-----------+----------+---------
+ id     | integer |           |          | 
+ data   | text    |           |          | 
+Indexes:
+    "idx_invis1" btree (data)
+
+\d idx_invis1
+Index "schema_to_reindex.idx_invis1"
+ Column | Type | Key? | Definition 
+--------+------+------+------------
+ data   | text | yes  | data
+btree, for table "schema_to_reindex.invis_test"
+
+-- Clean up
+DROP TABLE index_test;
+DROP TABLE join_test;
+DROP FUNCTION get_data_length;
+DROP FUNCTION show_index_status;
+DROP TABLE indcheckxmin_test CASCADE;
+DEALLOCATE idx_plan;
+DROP TABLE prep_idx_test;
+DROP TABLE part_tbl CASCADE;
+DROP TABLE vis_test;
+DROP TABLE invis_test;
 -- Failure for unauthorized user
 CREATE ROLE regress_reindexuser NOLOGIN;
 SET SESSION ROLE regress_reindexuser;
diff --git a/src/test/regress/sql/create_index.sql b/src/test/regress/sql/create_index.sql
index 6b3852dddd..27a736a864 100644
--- a/src/test/regress/sql/create_index.sql
+++ b/src/test/regress/sql/create_index.sql
@@ -1435,6 +1435,327 @@ END;
 -- concurrently
 REINDEX SCHEMA CONCURRENTLY schema_to_reindex;
 
+-- Test index visibility functionality
+
+CREATE TABLE index_test(
+    id INT PRIMARY KEY,
+    data TEXT,
+    num INT,
+    vector INT[],
+    range INT4RANGE
+);
+
+INSERT INTO index_test
+SELECT
+    g,
+    'data ' || g,
+    g % 100,
+    ARRAY[g, g+1, g+2],
+    int4range(g, g+10)
+FROM generate_series(1, 1000) g;
+
+-- Function for testing
+CREATE FUNCTION get_data_length(text) RETURNS INT AS $$
+    SELECT length($1);
+$$ LANGUAGE SQL IMMUTABLE;
+
+-- Helper function to show index status
+CREATE OR REPLACE FUNCTION show_index_status(index_name text)
+RETURNS TABLE (
+    indexrelid regclass,
+    indisvalid boolean,
+    indisready boolean,
+    indislive boolean,
+    indisvisible boolean
+) AS $$
+BEGIN
+    RETURN QUERY EXECUTE format('
+        SELECT indexrelid::regclass, indisvalid, indisready, indislive, indisvisible
+        FROM pg_index
+        WHERE indexrelid = %L::regclass', index_name);
+END;
+$$ LANGUAGE plpgsql;
+
+-- Create and test each index type
+-- 1. Basic single-column index
+CREATE INDEX idx_single ON index_test(data);
+SELECT show_index_status('idx_single');
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE data = 'data 500';
+ALTER INDEX idx_single INVISIBLE;
+SELECT show_index_status('idx_single');
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE data = 'data 500';
+ALTER INDEX idx_single VISIBLE;
+SELECT show_index_status('idx_single');
+
+-- 2. Multi-column index
+CREATE INDEX idx_multi ON index_test(num, data);
+SELECT show_index_status('idx_multi');
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE num = 50 AND data > 'data 500';
+ALTER INDEX idx_multi INVISIBLE;
+SELECT show_index_status('idx_multi');
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE num = 50 AND data > 'data 500';
+ALTER INDEX idx_multi VISIBLE;
+SELECT show_index_status('idx_multi');
+
+-- 3. Partial index
+CREATE INDEX idx_partial ON index_test(num) WHERE num < 50;
+SELECT show_index_status('idx_partial');
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE num = 25;
+ALTER INDEX idx_partial INVISIBLE;
+SELECT show_index_status('idx_partial');
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE num = 25;
+ALTER INDEX idx_partial VISIBLE;
+SELECT show_index_status('idx_partial');
+
+-- 4. Expression index
+CREATE INDEX idx_expression ON index_test((lower(data)));
+SELECT show_index_status('idx_expression');
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE lower(data) = 'data 500';
+ALTER INDEX idx_expression INVISIBLE;
+SELECT show_index_status('idx_expression');
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE lower(data) = 'data 500';
+ALTER INDEX idx_expression VISIBLE;
+SELECT show_index_status('idx_expression');
+
+-- 5. GIN index
+CREATE INDEX idx_gin ON index_test USING gin(vector);
+SELECT show_index_status('idx_gin');
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE vector @> ARRAY[500];
+ALTER INDEX idx_gin INVISIBLE;
+SELECT show_index_status('idx_gin');
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE vector @> ARRAY[500];
+ALTER INDEX idx_gin VISIBLE;
+SELECT show_index_status('idx_gin');
+
+-- 6. GiST index
+CREATE INDEX idx_gist ON index_test USING gist(range);
+SELECT show_index_status('idx_gist');
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE range && int4range(100, 110);
+ALTER INDEX idx_gist INVISIBLE;
+SELECT show_index_status('idx_gist');
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE range && int4range(100, 110);
+ALTER INDEX idx_gist VISIBLE;
+SELECT show_index_status('idx_gist');
+
+-- 7. Covering index
+CREATE INDEX idx_covering ON index_test(num) INCLUDE (data);
+SELECT show_index_status('idx_covering');
+EXPLAIN (COSTS OFF) SELECT num, data FROM index_test WHERE num = 50;
+ALTER INDEX idx_covering INVISIBLE;
+SELECT show_index_status('idx_covering');
+EXPLAIN (COSTS OFF) SELECT num, data FROM index_test WHERE num = 50;
+ALTER INDEX idx_covering VISIBLE;
+SELECT show_index_status('idx_covering');
+
+-- 8. Unique index
+CREATE UNIQUE INDEX idx_unique ON index_test(id, data);
+SELECT show_index_status('idx_unique');
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE id = 500 AND data = 'data 500';
+ALTER INDEX idx_unique INVISIBLE;
+SELECT show_index_status('idx_unique');
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE id = 500 AND data = 'data 500';
+ALTER INDEX idx_unique VISIBLE;
+SELECT show_index_status('idx_unique');
+
+-- 9. Function-based index
+CREATE INDEX idx_func ON index_test(get_data_length(data));
+SELECT show_index_status('idx_func');
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE get_data_length(data) = 10;
+ALTER INDEX idx_func INVISIBLE;
+SELECT show_index_status('idx_func');
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE get_data_length(data) = 10;
+ALTER INDEX idx_func VISIBLE;
+SELECT show_index_status('idx_func');
+
+-- 10. Join index
+CREATE TABLE join_test (id INT PRIMARY KEY, ref_id INT);
+INSERT INTO join_test SELECT g, g % 100 FROM generate_series(1, 1000) g;
+CREATE INDEX idx_join ON join_test(ref_id);
+SELECT show_index_status('idx_join');
+
+EXPLAIN (COSTS OFF)
+SELECT jt.id, it.data
+FROM join_test jt
+JOIN index_test it ON jt.ref_id = it.num
+WHERE jt.id BETWEEN 100 AND 200;
+
+-- Set all indexes to invisible to force seq scan
+ALTER INDEX idx_join INVISIBLE;
+ALTER INDEX join_test_pkey INVISIBLE;
+SELECT show_index_status('idx_join');
+SELECT show_index_status('join_test_pkey');
+
+EXPLAIN (COSTS OFF)
+SELECT jt.id, it.data
+FROM join_test jt
+JOIN index_test it ON jt.ref_id = it.num
+WHERE jt.id BETWEEN 100 AND 200;
+
+ALTER INDEX idx_join VISIBLE;
+ALTER INDEX join_test_pkey VISIBLE;
+SELECT show_index_status('idx_join');
+SELECT show_index_status('join_test_pkey');
+
+-- Test REINDEX CONCURRENTLY
+REINDEX INDEX CONCURRENTLY idx_join;
+SELECT show_index_status('idx_join');
+
+ALTER INDEX idx_join INVISIBLE;
+SELECT show_index_status('idx_join');
+REINDEX INDEX CONCURRENTLY idx_join;
+SELECT show_index_status('idx_join');
+
+SELECT pg_get_indexdef('idx_join'::regclass);
+ALTER INDEX idx_join VISIBLE;
+SELECT pg_get_indexdef('idx_join'::regclass);
+
+-- Test index visibility with indcheckxmin being true
+
+CREATE TABLE indcheckxmin_test(id int PRIMARY KEY);
+INSERT INTO indcheckxmin_test VALUES (1), (2), (3);
+CREATE INDEX CONCURRENTLY idx_checkxmin ON indcheckxmin_test(id);
+BEGIN;
+-- Simulate indcheckxmin being true
+UPDATE pg_index SET indcheckxmin = true WHERE indexrelid = 'idx_checkxmin'::regclass;
+ALTER INDEX idx_checkxmin INVISIBLE;  -- expect fail
+ROLLBACK;
+
+-- Test prepared statements with index visibility
+CREATE TABLE prep_idx_test (id int, data text);
+CREATE INDEX prep_idx1 ON prep_idx_test(data);
+INSERT INTO prep_idx_test SELECT g, 'data ' || g FROM generate_series(1,100) g;
+
+-- Test with visible index
+PREPARE idx_plan AS SELECT * FROM prep_idx_test WHERE data = $1;
+EXPLAIN (COSTS OFF) EXECUTE idx_plan('data 1');
+EXECUTE idx_plan('data 1');
+
+-- Test with invisible index
+ALTER INDEX prep_idx1 INVISIBLE;
+EXPLAIN (COSTS OFF) EXECUTE idx_plan('data 1');
+EXECUTE idx_plan('data 1');
+
+-- Test with use_invisible_index
+SET use_invisible_index TO on;
+EXPLAIN (COSTS OFF) EXECUTE idx_plan('data 1');
+EXECUTE idx_plan('data 1');
+SET use_invisible_index TO off;
+-- Assert plan cache is reset and index is not used
+EXPLAIN (COSTS OFF) EXECUTE idx_plan('data 1');
+
+-- Make index visible and test again
+ALTER INDEX prep_idx1 VISIBLE;
+EXPLAIN (COSTS OFF) EXECUTE idx_plan('data 1');
+EXECUTE idx_plan('data 1');
+
+-- Test index visibility with partitioned tables
+CREATE TABLE part_tbl(id int, data text) PARTITION BY RANGE(id);
+CREATE TABLE part1 PARTITION OF part_tbl FOR VALUES FROM (1) TO (100);
+CREATE TABLE part2 PARTITION OF part_tbl FOR VALUES FROM (100) TO (200);
+
+INSERT INTO part_tbl
+SELECT g, 'data ' || g
+FROM generate_series(1, 199) g;
+
+CREATE INDEX idx_part_tbl ON part_tbl(data);
+
+SELECT c.relname, i.indisvisible
+FROM pg_index i
+JOIN pg_class c ON i.indexrelid = c.oid
+WHERE c.relname LIKE 'idx_part_tbl%'
+ORDER BY c.relname;
+
+-- Force use of indexes to avoid flaky test results
+SET enable_seqscan = off;
+
+EXPLAIN (COSTS OFF)
+SELECT * FROM part_tbl WHERE data = 'data 50';
+
+ALTER INDEX idx_part_tbl INVISIBLE;
+
+SELECT c.relname, i.indisvisible
+FROM pg_index i
+JOIN pg_class c ON i.indexrelid = c.oid
+WHERE c.relname LIKE 'idx_part_tbl%'
+ORDER BY c.relname;
+
+-- Check query plan after setting invisible (should use seq scan)
+EXPLAIN (COSTS OFF)
+SELECT * FROM part_tbl WHERE data = 'data 50';
+
+SET use_invisible_index TO on;
+
+EXPLAIN (COSTS OFF)
+SELECT * FROM part_tbl WHERE data = 'data 50';
+
+SET use_invisible_index TO off;
+
+EXPLAIN (COSTS OFF)
+SELECT * FROM part_tbl WHERE data = 'data 50';
+
+ALTER INDEX idx_part_tbl VISIBLE;
+
+SELECT c.relname, i.indisvisible
+FROM pg_index i
+JOIN pg_class c ON i.indexrelid = c.oid
+WHERE c.relname LIKE 'idx_part_tbl%'
+ORDER BY c.relname;
+
+EXPLAIN (COSTS OFF)
+SELECT * FROM part_tbl WHERE data = 'data 50';
+
+SET enable_seqscan = on;
+
+-- Test REINDEX maintains visibility setting
+ALTER INDEX idx_part_tbl INVISIBLE;
+REINDEX INDEX idx_part_tbl;
+
+SELECT c.relname, i.indisvisible
+FROM pg_index i
+JOIN pg_class c ON i.indexrelid = c.oid
+WHERE c.relname LIKE 'idx_part_tbl%'
+ORDER BY c.relname;
+
+-- Test that index visibility is preserved after ALTER TABLE
+CREATE TABLE vis_test(id INT PRIMARY KEY, data text);
+\d vis_test
+
+ALTER INDEX vis_test_pkey INVISIBLE;
+\d vis_test
+
+ALTER TABLE vis_test ALTER COLUMN id SET DATA TYPE bigint;
+\d vis_test
+
+ALTER TABLE vis_test ALTER COLUMN id SET DATA TYPE int;
+\d vis_test
+
+ALTER INDEX vis_test_pkey VISIBLE;
+\d vis_test
+
+-- Test CREATE INDEX with INVISIBLE option
+CREATE TABLE invis_test(id int, data text);
+INSERT INTO invis_test SELECT g, 'data ' || g FROM generate_series(1,100) g;
+
+CREATE INDEX idx_invis1 ON invis_test(data) INVISIBLE;
+\d invis_test
+\d idx_invis1
+
+ALTER INDEX idx_invis1 VISIBLE;
+\d invis_test
+\d idx_invis1
+
+-- Clean up
+DROP TABLE index_test;
+DROP TABLE join_test;
+DROP FUNCTION get_data_length;
+DROP FUNCTION show_index_status;
+DROP TABLE indcheckxmin_test CASCADE;
+DEALLOCATE idx_plan;
+DROP TABLE prep_idx_test;
+DROP TABLE part_tbl CASCADE;
+DROP TABLE vis_test;
+DROP TABLE invis_test;
+
 -- Failure for unauthorized user
 CREATE ROLE regress_reindexuser NOLOGIN;
 SET SESSION ROLE regress_reindexuser;
-- 
2.39.5 (Apple Git-154)

#78Gurjeet Singh
gurjeet@singh.im
In reply to: David Rowley (#12)
Re: [PATCH] Re: Proposal to Enable/Disable Index using ALTER INDEX

On Sun, Sep 22, 2024 at 3:45 PM David Rowley <dgrowleyml@gmail.com> wrote:

I think the documents should also mention that disabling an index is a
useful way to verify an index is not being used before dropping it as
the index can be enabled again at the first sign that performance has
been effected. (It might also be good to mention that checking
pg_stat_user_indexes.idx_scan should be the first port of call when
checking for unused indexes)

While reviewing Shayon's v14 patch, I had removed text (quoted below) from the
ALTER INDEX docs that did not feel right in a command reference. I thought
of reading up on the history/discussion of the patch, and now I see why Shayon
chose to include an advice in ALTER INDEX docs.

+ indexes. If performance degrades after making an index invisible, it can be easily
+ be made visible using <literal>VISIBLE</literal>. Before making an index invisible, it's recommended
+ to check <structname>pg_stat_user_indexes</structname>.<structfield>idx_scan</structfield>
+ to identify potentially unused indexes.

I feel ALTER INDEX command reference doc is not the right place for this kind of
operational advice. Is there a better place in documentation for this kind of
advice? Or maybe it needs to be reworded to fit the command reference style?

Best regards,
Gurjeet
http://Gurje.et

#79Sami Imseih
samimseih@gmail.com
In reply to: Gurjeet Singh (#78)
Re: [PATCH] Re: Proposal to Enable/Disable Index using ALTER INDEX
+ indexes. If performance degrades after making an index invisible, it can be easily
+ be made visible using <literal>VISIBLE</literal>. Before making an index invisible, it's recommended
+ to check <structname>pg_stat_user_indexes</structname>.<structfield>idx_scan</structfield>
+ to identify potentially unused indexes.

I feel ALTER INDEX command reference doc is not the right place for this kind of
operational advice. Is there a better place in documentation for this kind of
advice? Or maybe it needs to be reworded to fit the command reference style?

I agree with you.

What about we add this wording in the following section [0]https://www.postgresql.org/docs/current/indexes-examine.html? This
section discusses techniques
for experimenting with indexes. It says,
".... A good deal of experimentation is often necessary. The rest of
this section gives some tips for that:...."

A discussion about invisible indexes as one of the tools for
experimentation can be added here.
What do you think?

[0]: https://www.postgresql.org/docs/current/indexes-examine.html

--
Sami Imseih
Amazon Web Services (AWS)

#80Gurjeet Singh
gurjeet@singh.im
In reply to: Sami Imseih (#79)
Re: [PATCH] Re: Proposal to Enable/Disable Index using ALTER INDEX

On Wed Apr 2, 2025 at 6:58 PM PDT, Sami Imseih wrote:

+ indexes. If performance degrades after making an index invisible, it can be easily
+ be made visible using <literal>VISIBLE</literal>. Before making an index invisible, it's recommended
+ to check <structname>pg_stat_user_indexes</structname>.<structfield>idx_scan</structfield>
+ to identify potentially unused indexes.

I feel ALTER INDEX command reference doc is not the right place for this kind of
operational advice. Is there a better place in documentation for this kind of
advice? Or maybe it needs to be reworded to fit the command reference style?

I agree with you.

What about we add this wording in the following section [0]? This
section discusses techniques
for experimenting with indexes. It says,
".... A good deal of experimentation is often necessary. The rest of
this section gives some tips for that:...."

A discussion about invisible indexes as one of the tools for
experimentation can be added here.
What do you think?

[0] https://www.postgresql.org/docs/current/indexes-examine.html

That seems like a very good location for this advice. But the current
set of bullet points are all directed towards "... a general procedure
for determining which indexes to create". I propose that a new paragrph,
not a bullet point, be added towards the end of that section which
addresses the options of steps to take before dropping an index.
Something like the following:

Sometimes you may notice that an index is not being used anymore by the
application queries. In such cases, it is a good idea to investigate if
such an index can be dropped, because an index that is not being used
for query optimization still consumes resources and slows down INSERT,
UPDATE, and DELETE commands. To aid in such an investigation, look at
the pg_stat_user_indexes.idx_scan count for the index.

To determine the performance effects of dropping the index, without
actually dropping the said index, you may mark the index invisible to
the planner by using the ALTER INDEX ... INVISIIBLE command. If it turns
out that doing so causes a performance degradation, the index can be
quickly made visible to the planner for query optimization by using the
ALTER INDEX ... VISIBLE command.

Thoughts?

Best regards,
Gurjeet
http://Gurje.et

#81Sami Imseih
samimseih@gmail.com
In reply to: Gurjeet Singh (#80)
Re: [PATCH] Re: Proposal to Enable/Disable Index using ALTER INDEX

That seems like a very good location for this advice. But the current
set of bullet points are all directed towards "... a general procedure
for determining which indexes to create". I propose that a new paragrph,
not a bullet point, be added towards the end of that section which
addresses the options of steps to take before dropping an index.
Something like the following:

Thoughts?

This new feature provides the ability to experiment with indexes to
create ( or drop ),
so I don't think it deviates from the purpose of this paragraphs.

This patch will provide the ability for the user to create an index as initially
invisible and a GUC, use_invisible_index if set to TRUE to experiment with
the new index to see if it improves performance. So, I think providing this
pattern to experiment with a new index will fit nicely as a new bulletpoint.

--
Sami Imseih
Amazon Web Services (AWS)

#82Shayon Mukherjee
shayonj@gmail.com
In reply to: Sami Imseih (#81)
1 attachment(s)
Re: [PATCH] Re: Proposal to Enable/Disable Index using ALTER INDEX

On Wed, Apr 2, 2025 at 10:53 PM Sami Imseih <samimseih@gmail.com> wrote:

That seems like a very good location for this advice. But the current
set of bullet points are all directed towards "... a general procedure
for determining which indexes to create". I propose that a new paragrph,
not a bullet point, be added towards the end of that section which
addresses the options of steps to take before dropping an index.
Something like the following:

Thoughts?

This new feature provides the ability to experiment with indexes to
create ( or drop ),
so I don't think it deviates from the purpose of this paragraphs.

This patch will provide the ability for the user to create an index as
initially
invisible and a GUC, use_invisible_index if set to TRUE to experiment with
the new index to see if it improves performance. So, I think providing this
pattern to experiment with a new index will fit nicely as a new
bulletpoint.

Thank you for the feedback and pointers Sami and Gurjeet. Good call on [0]https://www.postgresql.org/docs/current/indexes-examine.html
being a good place for operational advice. I have gone ahead and removed
the advice about "pg_stat_user_indexes.idx_scan"
from doc/src/sgml/ref/alter_index.sgml and
updated doc/src/sgml/indices.sgml to include a new bullet point with also a
reference to use_invisible_index. Let me know how it sounds and if there is
any feedback.

Also, rebased.

Thank you
Shayon

[0]: https://www.postgresql.org/docs/current/indexes-examine.html

Attachments:

v15-0001-Introduce-the-ability-to-set-index-visibility-us.patchapplication/octet-stream; name=v15-0001-Introduce-the-ability-to-set-index-visibility-us.patchDownload
From b241e6a70bd8812b9c6b3fc1e2f7e52b29e52fa4 Mon Sep 17 00:00:00 2001
From: Shayon Mukherjee <shayonj@gmail.com>
Date: Sun, 12 Jan 2025 14:34:48 -0500
Subject: [PATCH v15] Introduce the ability to set index visibility using ALTER
 INDEX

This patch introduces index visibility control using ALTER INDEX and CREATE INDEX
commands.

Original motivation for the problem and proposal for a patch
can be found at [1].

This patch passes all the existing specs and the newly added regression tests. The patch
is ready for review and test. It compiles, so the patch can be applied for testing as well.

Note: The patch has gone through a few iterations. Earlier versions of the patch had the ENABLE/DISABLE grammar.
The current version has the VISIBLE/INVISIBLE grammar. So, you will the local variable names using the new grammar accordingly.

Implementation details:

- New Grammar:
  * ALTER INDEX ... VISIBLE/INVISIBLE
  * CREATE INDEX ... INVISIBLE

- Default state is visible. Indexes are only invisible when explicitly
  instructed via CREATE INDEX ... INVISIBLE or ALTER INDEX ... INVISIBLE.

- Primary Key and Unique constraint indexes are always visible. The
  VISIBLE/INVISIBLE grammar is supported for these types of indexes and they can
  be made invisible via ALTER INDEX ... INVISIBLE.

- ALTER INDEX ... VISIBLE/INVISIBLE performs update on the relevant row in pg_index
  catalog

- pg_get_indexdef() supports the new functionality and grammar. This change is
  reflected in \d output for tables and pg_dump. We show the INVISIBLE syntax accordingly.

- Added force_invisible_index GUC parameter that forces the planner to use invisible
  indexes. This is useful for testing and validating index behavior without changing
  their visibility state. Based on feedback from Sami S [2]

- Updated create_index.sql regression test to cover the new grammar and verify
  that invisible indexes are not used in queries. The test covers:

  - Basic single-column and multi-column indexes
  - Partial indexes
  - Expression indexes
  - Join indexes
  - GIN and GiST indexes
  - Covering indexes
  - Range indexes
  - Unique indexes and constraints

- Adds a new indisvisible attribute to the IndexOptInfo structure.

- Modifies get_relation_info in plancat.c to skip invisible indexes entirely, thus reducing the number of places we need to check if an index is invisible or not. Inspired by the conversations start at [3].
  - I chose to modify the logic within get_relation_info as compared to, say, reducing the cost to make the planner not consider an index during planning, mostly to keep the number of changes being introduced to a minimum and also the logic itself being self-contained and easier to understand perhaps (?).

- No changes are made to stop the index from getting maintained. This way we ensure no
  data loss or corruption when index is made visible again.

- TOAST indexes are supported and visible by default as well.

- REINDEX CONCURRENTLY is supported as well and existing state of pg_index.indisvisible
  is carried over accordingly.

- See the changes in create_index.sql to get an idea of the grammar and sql statements.

- See the changes in create_index.out to get an idea of the catalogue states and EXPLAIN
  output to see when an index is getting used or isn't (when invisible).

- Incorporated DavidR's feedback from [4] around documentation and also you will see that by skipping invisible indexes entirely from get_relation_info in plancat.c (as mentioned above), we address the other mentioned issues as well.

- Lastly, protects against the case where indcheckxmin is true by raising ERRCODE_OBJECT_NOT_IN_PREREQUISITE_STATE.

Looking forward to any and all feedback on this patch, including but not limited to code quality, tests, fundamental logic.

[1] https://www.postgresql.org/message-id/CANqtF-oXKe0M%3D0QOih6H%2BsZRjE2BWAbkW_1%2B9nMEAMLxUJg5jA%40mail.gmail.com
[2] https://www.postgresql.org/message-id/CAA5RZ0udzydObMDi65C59-oq54B9ZmjSZ1wVH3h%2Bv4XiVm6QDA%40mail.gmail.com
[3] https://www.postgresql.org/message-id/3465209.1727202064%40sss.pgh.pa.us
[4] https://www.postgresql.org/message-id/CAApHDvpUNu%3DiVcdJ74sypvgeaCF%2Btfpyb8VRhZaF7DTd1xVr7g%40mail.gmail.com
---
 doc/src/sgml/catalogs.sgml                    |  11 +
 doc/src/sgml/config.sgml                      |  16 +
 doc/src/sgml/indices.sgml                     |  21 +
 doc/src/sgml/ref/alter_index.sgml             |  36 +
 doc/src/sgml/ref/create_index.sgml            |  29 +
 src/backend/bootstrap/bootparse.y             |   2 +
 src/backend/catalog/index.c                   |  31 +-
 src/backend/catalog/toasting.c                |   2 +-
 src/backend/commands/indexcmds.c              |   4 +
 src/backend/commands/tablecmds.c              |  92 +-
 src/backend/optimizer/util/plancat.c          |  30 +-
 src/backend/parser/gram.y                     |  56 +-
 src/backend/parser/parse_utilcmd.c            |   3 +
 src/backend/utils/adt/ruleutils.c             |   4 +
 src/backend/utils/cache/relcache.c            |   1 +
 src/backend/utils/misc/guc_tables.c           |  10 +
 src/backend/utils/misc/postgresql.conf.sample |   1 +
 src/bin/pg_dump/pg_dump.c                     |  21 +-
 src/bin/pg_dump/pg_dump.h                     |   2 +
 src/bin/pg_dump/t/002_pg_dump.pl              |  29 +
 src/bin/psql/describe.c                       |  15 +-
 src/bin/psql/tab-complete.in.c                |   3 +-
 src/include/catalog/index.h                   |   2 +-
 src/include/catalog/pg_index.h                |   2 +
 src/include/nodes/parsenodes.h                |   4 +
 src/include/optimizer/optimizer.h             |   5 +
 src/include/parser/kwlist.h                   |   2 +
 src/include/utils/guc_hooks.h                 |   1 +
 src/test/modules/test_ddl_deparse/Makefile    |   3 +-
 .../test_ddl_deparse/expected/alter_index.out |  29 +
 src/test/modules/test_ddl_deparse/meson.build |   1 +
 .../test_ddl_deparse/sql/alter_index.sql      |  18 +
 .../test_ddl_deparse/test_ddl_deparse.c       |   6 +
 src/test/regress/expected/create_index.out    | 795 ++++++++++++++++++
 src/test/regress/sql/create_index.sql         | 321 +++++++
 35 files changed, 1582 insertions(+), 26 deletions(-)
 create mode 100644 src/test/modules/test_ddl_deparse/expected/alter_index.out
 create mode 100644 src/test/modules/test_ddl_deparse/sql/alter_index.sql

diff --git a/doc/src/sgml/catalogs.sgml b/doc/src/sgml/catalogs.sgml
index 45ba9c5118..66df797913 100644
--- a/doc/src/sgml/catalogs.sgml
+++ b/doc/src/sgml/catalogs.sgml
@@ -4618,6 +4618,17 @@ SCRAM-SHA-256$<replaceable>&lt;iteration count&gt;</replaceable>:<replaceable>&l
        partial index.
       </para></entry>
      </row>
+
+     <row>
+      <entry role="catalog_table_entry"><para role="column_definition">
+       <structfield>indisvisible</structfield> <type>bool</type>
+      </para>
+      <para>
+       If true, the index is currently visible to the planner and may be used for queries.
+       If false, the index is invisible and may not be used for queries,
+       but is still updated when the table is modified. Default is true.
+      </para></entry>
+     </row>
     </tbody>
    </tgroup>
   </table>
diff --git a/doc/src/sgml/config.sgml b/doc/src/sgml/config.sgml
index fea683cb49..b0925baf90 100644
--- a/doc/src/sgml/config.sgml
+++ b/doc/src/sgml/config.sgml
@@ -5778,6 +5778,22 @@ ANY <replaceable class="parameter">num_sync</replaceable> ( <replaceable class="
       </listitem>
      </varlistentry>
 
+     <varlistentry id="guc-force-invisible-index" xreflabel="use_invisible_index">
+      <term><varname>use_invisible_index</varname> (<type>boolean</type>)
+      <indexterm>
+       <primary><varname>use_invisible_index</varname> configuration parameter</primary>
+      </indexterm>
+      </term>
+      <listitem>
+       <para>
+        Forces the query planner to consider indexes that have been marked as invisible using
+        <command>ALTER INDEX ... INVISIBLE</command>. This parameter is useful for selective
+        use of invisible indexes in specific application contexts. The default
+        is <literal>off</literal>.
+       </para>
+      </listitem>
+     </varlistentry>
+
      </variablelist>
      </sect2>
      <sect2 id="runtime-config-query-constants">
diff --git a/doc/src/sgml/indices.sgml b/doc/src/sgml/indices.sgml
index 9c4f76abf0..97bb599a05 100644
--- a/doc/src/sgml/indices.sgml
+++ b/doc/src/sgml/indices.sgml
@@ -1673,6 +1673,27 @@ CREATE INDEX test1c_content_y_index ON test1c (content COLLATE "y");
      <productname>PostgreSQL</productname> developers to examine the issue.
     </para>
    </listitem>
+
+   <listitem>
+    <para>
+     Invisible indexes provide a convenient way to experiment with indexes
+     without needing to fully drop and recreate them. You can create a new index as
+     invisible with <command>CREATE INDEX ... INVISIBLE</command> or mark
+     an existing index invisible with <command>ALTER INDEX ... INVISIBLE</command>.
+     When an index is invisible, the planner will ignore it by default.
+     To test the index's effect on performance, set the
+     <varname>use_invisible_index</varname> parameter to <literal>on</literal>.
+     This allows you to compare query performance with and without the index
+     before making it visible to all queries with
+     <command>ALTER INDEX ... VISIBLE</command>.
+    </para>
+    <para>
+     Similarly, before dropping an existing index that appears unused,
+     consider marking it invisible to verify that query performance doesn't
+     degrade. Check <structname>pg_stat_user_indexes</structname>.<structfield>idx_scan</structfield>
+     to identify potentially unused indexes.
+    </para>
+   </listitem>
   </itemizedlist>
  </sect1>
 </chapter>
diff --git a/doc/src/sgml/ref/alter_index.sgml b/doc/src/sgml/ref/alter_index.sgml
index 1d42d05d85..a49d28a52d 100644
--- a/doc/src/sgml/ref/alter_index.sgml
+++ b/doc/src/sgml/ref/alter_index.sgml
@@ -31,6 +31,7 @@ ALTER INDEX [ IF EXISTS ] <replaceable class="parameter">name</replaceable> ALTE
     SET STATISTICS <replaceable class="parameter">integer</replaceable>
 ALTER INDEX ALL IN TABLESPACE <replaceable class="parameter">name</replaceable> [ OWNED BY <replaceable class="parameter">role_name</replaceable> [, ... ] ]
     SET TABLESPACE <replaceable class="parameter">new_tablespace</replaceable> [ NOWAIT ]
+ALTER INDEX [ IF EXISTS ] <replaceable class="parameter">name</replaceable> { VISIBLE | INVISIBLE }
 </synopsis>
  </refsynopsisdiv>
 
@@ -159,6 +160,27 @@ ALTER INDEX ALL IN TABLESPACE <replaceable class="parameter">name</replaceable>
     </listitem>
    </varlistentry>
 
+   <varlistentry>
+    <term><literal>VISIBLE</literal></term>
+    <listitem>
+     <para>
+      Make the specified index visible. The index will be used for query planning.
+     </para>
+    </listitem>
+   </varlistentry>
+
+   <varlistentry>
+    <term><literal>INVISIBLE</literal></term>
+    <listitem>
+     <para>
+      Make the specified index invisible. The index will not be used for queries.
+      This can be useful for testing query performance with and without specific
+      indexes. If performance degrades after making an index invisible, it can be easily
+      be made visible using <literal>VISIBLE</literal>.
+     </para>
+    </listitem>
+   </varlistentry>
+
   </variablelist>
   </para>
 
@@ -301,6 +323,20 @@ CREATE INDEX coord_idx ON measured (x, y, (z + t));
 ALTER INDEX coord_idx ALTER COLUMN 3 SET STATISTICS 1000;
 </programlisting></para>
 
+  <para>
+   To make an index visible:
+<programlisting>
+ALTER INDEX idx_name VISIBLE;
+</programlisting>
+  </para>
+
+  <para>
+   To make an index invisible:
+<programlisting>
+ALTER INDEX idx_name INVISIBLE;
+</programlisting>
+  </para>
+
  </refsect1>
 
  <refsect1>
diff --git a/doc/src/sgml/ref/create_index.sgml b/doc/src/sgml/ref/create_index.sgml
index 208389e800..90d7d90a2b 100644
--- a/doc/src/sgml/ref/create_index.sgml
+++ b/doc/src/sgml/ref/create_index.sgml
@@ -28,6 +28,7 @@ CREATE [ UNIQUE ] INDEX [ CONCURRENTLY ] [ [ IF NOT EXISTS ] <replaceable class=
     [ WITH ( <replaceable class="parameter">storage_parameter</replaceable> [= <replaceable class="parameter">value</replaceable>] [, ... ] ) ]
     [ TABLESPACE <replaceable class="parameter">tablespace_name</replaceable> ]
     [ WHERE <replaceable class="parameter">predicate</replaceable> ]
+    [ INVISIBLE ]
 </synopsis>
  </refsynopsisdiv>
 
@@ -380,6 +381,19 @@ CREATE [ UNIQUE ] INDEX [ CONCURRENTLY ] [ [ IF NOT EXISTS ] <replaceable class=
       </listitem>
      </varlistentry>
 
+    <varlistentry>
+      <term><literal>INVISIBLE</literal></term>
+      <listitem>
+       <para>
+        Creates the index in an invisible state (default visible). An invisible index is
+        not used by the query planner for queries, but it is still maintained
+        when the underlying table data changes. This can be useful when you want to create
+        an index without immediately impacting query planning, allowing you to make it
+        visible later at a more convenient time. The index can be made visible later
+        using <command>ALTER INDEX ... VISIBLE</command>.
+       </para>
+      </listitem>
+     </varlistentry>
     </variablelist>
 
   <refsect2 id="sql-createindex-storage-parameters" xreflabel="Index Storage Parameters">
@@ -701,6 +715,14 @@ Indexes:
     partitioned index is a metadata only operation.
    </para>
 
+  <para>
+   When creating an index with the <literal>INVISIBLE</literal> option, the index
+   will be created but not used for query planning. This can be useful for
+   preparing an index in advance of its use, or for testing purposes. The index
+   will still be maintained as the table is modified, so it can be made visible
+   later without needing to be rebuilt. By default all new indexes are visible.
+  </para>
+
   </refsect2>
  </refsect1>
 
@@ -980,6 +1002,13 @@ SELECT * FROM points
 CREATE INDEX CONCURRENTLY sales_quantity_index ON sales_table (quantity);
 </programlisting></para>
 
+  <para>
+   To create an index on the table <literal>test_table</literal> with the default
+   name, but have it initially invisible:
+<programlisting>
+CREATE INDEX ON test_table (col1) INVISIBLE;
+</programlisting>
+  </para>
  </refsect1>
 
  <refsect1>
diff --git a/src/backend/bootstrap/bootparse.y b/src/backend/bootstrap/bootparse.y
index 9833f52c1b..ea21511a20 100644
--- a/src/backend/bootstrap/bootparse.y
+++ b/src/backend/bootstrap/bootparse.y
@@ -303,6 +303,7 @@ Boot_DeclareIndexStmt:
 					stmt->concurrent = false;
 					stmt->if_not_exists = false;
 					stmt->reset_default_tblspc = false;
+					stmt->isvisible = true;
 
 					/* locks and races need not concern us in bootstrap mode */
 					relationId = RangeVarGetRelid(stmt->relation, NoLock,
@@ -356,6 +357,7 @@ Boot_DeclareUniqueIndexStmt:
 					stmt->concurrent = false;
 					stmt->if_not_exists = false;
 					stmt->reset_default_tblspc = false;
+					stmt->isvisible = true;
 
 					/* locks and races need not concern us in bootstrap mode */
 					relationId = RangeVarGetRelid(stmt->relation, NoLock,
diff --git a/src/backend/catalog/index.c b/src/backend/catalog/index.c
index 739a92bdcc..2d8ceb60ce 100644
--- a/src/backend/catalog/index.c
+++ b/src/backend/catalog/index.c
@@ -119,7 +119,8 @@ static void UpdateIndexRelation(Oid indexoid, Oid heapoid,
 								bool isexclusion,
 								bool immediate,
 								bool isvalid,
-								bool isready);
+								bool isready,
+								bool isvisible);
 static void index_update_stats(Relation rel,
 							   bool hasindex,
 							   double reltuples);
@@ -571,7 +572,8 @@ UpdateIndexRelation(Oid indexoid,
 					bool isexclusion,
 					bool immediate,
 					bool isvalid,
-					bool isready)
+					bool isready,
+					bool isvisible)
 {
 	int2vector *indkey;
 	oidvector  *indcollation;
@@ -649,6 +651,7 @@ UpdateIndexRelation(Oid indexoid,
 	values[Anum_pg_index_indisready - 1] = BoolGetDatum(isready);
 	values[Anum_pg_index_indislive - 1] = BoolGetDatum(true);
 	values[Anum_pg_index_indisreplident - 1] = BoolGetDatum(false);
+	values[Anum_pg_index_indisvisible - 1] = BoolGetDatum(isvisible);
 	values[Anum_pg_index_indkey - 1] = PointerGetDatum(indkey);
 	values[Anum_pg_index_indcollation - 1] = PointerGetDatum(indcollation);
 	values[Anum_pg_index_indclass - 1] = PointerGetDatum(indclass);
@@ -714,6 +717,8 @@ UpdateIndexRelation(Oid indexoid,
  *			already exists.
  *		INDEX_CREATE_PARTITIONED:
  *			create a partitioned index (table must be partitioned)
+ *		INDEX_CREATE_VISIBLE:
+ *			create the index as visible to query planner
  * constr_flags: flags passed to index_constraint_create
  *		(only if INDEX_CREATE_ADD_CONSTRAINT is set)
  * allow_system_table_mods: allow table to be a system catalog
@@ -759,6 +764,7 @@ index_create(Relation heapRelation,
 	bool		invalid = (flags & INDEX_CREATE_INVALID) != 0;
 	bool		concurrent = (flags & INDEX_CREATE_CONCURRENT) != 0;
 	bool		partitioned = (flags & INDEX_CREATE_PARTITIONED) != 0;
+	bool		isvisible = (flags & INDEX_CREATE_VISIBLE) != 0;
 	char		relkind;
 	TransactionId relfrozenxid;
 	MultiXactId relminmxid;
@@ -1042,13 +1048,15 @@ index_create(Relation heapRelation,
 	 *	  (Or, could define a rule to maintain the predicate) --Nels, Feb '92
 	 * ----------------
 	 */
+
 	UpdateIndexRelation(indexRelationId, heapRelationId, parentIndexRelid,
 						indexInfo,
 						collationIds, opclassIds, coloptions,
 						isprimary, is_exclusion,
 						(constr_flags & INDEX_CONSTR_CREATE_DEFERRABLE) == 0,
 						!concurrent && !invalid,
-						!concurrent);
+						!concurrent,
+						isvisible);
 
 	/*
 	 * Register relcache invalidation on the indexes' heap relation, to
@@ -1317,6 +1325,8 @@ index_concurrently_create_copy(Relation heapRelation, Oid oldIndexId,
 	List	   *indexColNames = NIL;
 	List	   *indexExprs = NIL;
 	List	   *indexPreds = NIL;
+	Form_pg_index indexForm;
+	bits16		createFlags;
 
 	indexRelation = index_open(oldIndexId, RowExclusiveLock);
 
@@ -1344,6 +1354,9 @@ index_concurrently_create_copy(Relation heapRelation, Oid oldIndexId,
 											Anum_pg_index_indoption);
 	indcoloptions = (int2vector *) DatumGetPointer(colOptionDatum);
 
+	/* Get the visibility state of the original index */
+	indexForm = (Form_pg_index) GETSTRUCT(indexTuple);
+
 	/* Fetch reloptions of index if any */
 	classTuple = SearchSysCache1(RELOID, ObjectIdGetDatum(oldIndexId));
 	if (!HeapTupleIsValid(classTuple))
@@ -1435,6 +1448,16 @@ index_concurrently_create_copy(Relation heapRelation, Oid oldIndexId,
 		stattargets[i].isnull = isnull;
 	}
 
+	/*
+	 * Determine the create flags for the new index. We always use SKIP_BUILD
+	 * and CONCURRENT for concurrent reindexing. If the original index was
+	 * visible, we also set the VISIBLE flag to maintain the same state in the
+	 * new index.
+	 */
+	createFlags = INDEX_CREATE_SKIP_BUILD | INDEX_CREATE_CONCURRENT;
+	if (indexForm->indisvisible)
+		createFlags |= INDEX_CREATE_VISIBLE;
+
 	/*
 	 * Now create the new index.
 	 *
@@ -1458,7 +1481,7 @@ index_concurrently_create_copy(Relation heapRelation, Oid oldIndexId,
 							  indcoloptions->values,
 							  stattargets,
 							  reloptionsDatum,
-							  INDEX_CREATE_SKIP_BUILD | INDEX_CREATE_CONCURRENT,
+							  createFlags,
 							  0,
 							  true, /* allow table to be a system catalog? */
 							  false,	/* is_internal? */
diff --git a/src/backend/catalog/toasting.c b/src/backend/catalog/toasting.c
index 874a8fc89a..7721d16fd3 100644
--- a/src/backend/catalog/toasting.c
+++ b/src/backend/catalog/toasting.c
@@ -325,7 +325,7 @@ create_toast_table(Relation rel, Oid toastOid, Oid toastIndexOid,
 				 BTREE_AM_OID,
 				 rel->rd_rel->reltablespace,
 				 collationIds, opclassIds, NULL, coloptions, NULL, (Datum) 0,
-				 INDEX_CREATE_IS_PRIMARY, 0, true, true, NULL);
+				 INDEX_CREATE_IS_PRIMARY | INDEX_CREATE_VISIBLE, 0, true, true, NULL);
 
 	table_close(toast_rel, NoLock);
 
diff --git a/src/backend/commands/indexcmds.c b/src/backend/commands/indexcmds.c
index 33c2106c17..693f23e8d6 100644
--- a/src/backend/commands/indexcmds.c
+++ b/src/backend/commands/indexcmds.c
@@ -1222,6 +1222,10 @@ DefineIndex(Oid tableId,
 		flags |= INDEX_CREATE_PARTITIONED;
 	if (stmt->primary)
 		flags |= INDEX_CREATE_IS_PRIMARY;
+	if (stmt->isvisible)
+		flags |= INDEX_CREATE_VISIBLE;
+	else
+		flags &= ~INDEX_CREATE_VISIBLE;
 
 	/*
 	 * If the table is partitioned, and recursion was declined but partitions
diff --git a/src/backend/commands/tablecmds.c b/src/backend/commands/tablecmds.c
index 4397123398..0f31579fc0 100644
--- a/src/backend/commands/tablecmds.c
+++ b/src/backend/commands/tablecmds.c
@@ -735,7 +735,8 @@ static List *GetParentedForeignKeyRefs(Relation partition);
 static void ATDetachCheckNoForeignKeyRefs(Relation partition);
 static char GetAttributeCompression(Oid atttypid, const char *compression);
 static char GetAttributeStorage(Oid atttypid, const char *storagemode);
-
+static void ATExecSetIndexVisibility(Relation rel, bool visible);
+static bool GetIndexVisibility(Oid indexOid);
 
 /* ----------------------------------------------------------------
  *		DefineRelation
@@ -4830,6 +4831,11 @@ AlterTableGetLockLevel(List *cmds)
 				cmd_lockmode = ShareUpdateExclusiveLock;
 				break;
 
+			case AT_SetIndexVisible:
+			case AT_SetIndexInvisible:
+				cmd_lockmode = ShareUpdateExclusiveLock;
+				break;
+
 			default:			/* oops */
 				elog(ERROR, "unrecognized alter table type: %d",
 					 (int) cmd->subtype);
@@ -5265,6 +5271,13 @@ ATPrepCmd(List **wqueue, Relation rel, AlterTableCmd *cmd,
 			/* No command-specific prep needed */
 			pass = AT_PASS_MISC;
 			break;
+		case AT_SetIndexVisible:
+		case AT_SetIndexInvisible:
+			ATSimplePermissions(cmd->subtype, rel, ATT_INDEX | ATT_PARTITIONED_INDEX);
+			ATSimpleRecursion(wqueue, rel, cmd, true, lockmode, context);
+			/* No command-specific prep needed */
+			pass = AT_PASS_MISC;
+			break;
 		default:				/* oops */
 			elog(ERROR, "unrecognized alter table type: %d",
 				 (int) cmd->subtype);
@@ -5661,6 +5674,12 @@ ATExecCmd(List **wqueue, AlteredTableInfo *tab,
 		case AT_DetachPartitionFinalize:
 			address = ATExecDetachPartitionFinalize(rel, ((PartitionCmd *) cmd->def)->name);
 			break;
+		case AT_SetIndexVisible:
+			ATExecSetIndexVisibility(rel, true);
+			break;
+		case AT_SetIndexInvisible:
+			ATExecSetIndexVisibility(rel, false);
+			break;
 		default:				/* oops */
 			elog(ERROR, "unrecognized alter table type: %d",
 				 (int) cmd->subtype);
@@ -6607,6 +6626,8 @@ alter_table_type_to_string(AlterTableType cmdtype)
 			return "DROP COLUMN";
 		case AT_AddIndex:
 		case AT_ReAddIndex:
+		case AT_SetIndexVisible:
+		case AT_SetIndexInvisible:
 			return NULL;		/* not real grammar */
 		case AT_AddConstraint:
 		case AT_ReAddConstraint:
@@ -15413,6 +15434,8 @@ ATPostAlterTypeParse(Oid oldId, Oid oldRelId, Oid refRelId, char *cmd,
 			stmt->reset_default_tblspc = true;
 			/* keep the index's comment */
 			stmt->idxcomment = GetComment(oldId, RelationRelationId, 0);
+			/* preserve the index's visibility status */
+			stmt->isvisible = GetIndexVisibility(oldId);
 
 			newcmd = makeNode(AlterTableCmd);
 			newcmd->subtype = AT_ReAddIndex;
@@ -15443,6 +15466,8 @@ ATPostAlterTypeParse(Oid oldId, Oid oldRelId, Oid refRelId, char *cmd,
 					indstmt->idxcomment = GetComment(indoid,
 													 RelationRelationId, 0);
 					indstmt->reset_default_tblspc = true;
+					/* preserve the index's visibility status */
+					indstmt->isvisible = GetIndexVisibility(indoid);
 
 					cmd->subtype = AT_ReAddIndex;
 					tab->subcmds[AT_PASS_OLD_INDEX] =
@@ -21798,3 +21823,68 @@ GetAttributeStorage(Oid atttypid, const char *storagemode)
 
 	return cstorage;
 }
+
+/*
+ * ATExecSetIndexVisibility
+ * Performs a catalog update to mark an index as visible or invisible in pg_index.
+ */
+static void
+ATExecSetIndexVisibility(Relation rel, bool visible)
+{
+	Oid			indexOid = RelationGetRelid(rel);
+	Oid			heapOid;
+	Relation	pg_index;
+	Relation	heapRel;
+	HeapTuple	indexTuple;
+	Form_pg_index indexForm;
+
+	heapOid = IndexGetRelation(indexOid, false);
+	heapRel = table_open(heapOid, AccessShareLock);
+	pg_index = table_open(IndexRelationId, RowExclusiveLock);
+
+	indexTuple = SearchSysCacheCopy1(INDEXRELID, ObjectIdGetDatum(indexOid));
+	if (!HeapTupleIsValid(indexTuple))
+		elog(ERROR, "cache lookup failed for index %u", indexOid);
+
+	indexForm = (Form_pg_index) GETSTRUCT(indexTuple);
+	if (indexForm->indcheckxmin)
+		ereport(ERROR,
+				errcode(ERRCODE_OBJECT_NOT_IN_PREREQUISITE_STATE),
+				errmsg("cannot update index visibility while indcheckxmin is true"),
+				errhint("Wait for all transactions that might see inconsistent HOT chains to complete"));
+
+	if (indexForm->indisvisible != visible)
+	{
+		indexForm->indisvisible = visible;
+		CatalogTupleUpdate(pg_index, &indexTuple->t_self, indexTuple);
+
+		CacheInvalidateRelcache(heapRel);
+		InvokeObjectPostAlterHook(IndexRelationId, indexOid, 0);
+		CommandCounterIncrement();
+	}
+
+	heap_freetuple(indexTuple);
+	table_close(pg_index, RowExclusiveLock);
+	table_close(heapRel, AccessShareLock);
+}
+
+/*
+* Get index visibility status from pg_index
+*/
+static bool
+GetIndexVisibility(Oid indexOid)
+{
+	HeapTuple	indexTuple;
+	Form_pg_index indexForm;
+	bool		isvisible;
+
+	indexTuple = SearchSysCache1(INDEXRELID, ObjectIdGetDatum(indexOid));
+	if (!HeapTupleIsValid(indexTuple))
+		elog(ERROR, "cache lookup failed for index %u", indexOid);
+
+	indexForm = (Form_pg_index) GETSTRUCT(indexTuple);
+	isvisible = indexForm->indisvisible;
+	ReleaseSysCache(indexTuple);
+
+	return isvisible;
+}
diff --git a/src/backend/optimizer/util/plancat.c b/src/backend/optimizer/util/plancat.c
index 441684a72b..f204d54aff 100644
--- a/src/backend/optimizer/util/plancat.c
+++ b/src/backend/optimizer/util/plancat.c
@@ -47,7 +47,9 @@
 #include "storage/bufmgr.h"
 #include "tcop/tcopprot.h"
 #include "utils/builtins.h"
+#include "utils/guc_hooks.h"
 #include "utils/lsyscache.h"
+#include "utils/plancache.h"
 #include "utils/partcache.h"
 #include "utils/rel.h"
 #include "utils/snapmgr.h"
@@ -55,6 +57,7 @@
 
 /* GUC parameter */
 int			constraint_exclusion = CONSTRAINT_EXCLUSION_PARTITION;
+bool		use_invisible_index = false;
 
 /* Hook for plugins to get control in get_relation_info() */
 get_relation_info_hook_type get_relation_info_hook = NULL;
@@ -254,13 +257,13 @@ get_relation_info(PlannerInfo *root, Oid relationObjectId, bool inhparent,
 			index = indexRelation->rd_index;
 
 			/*
-			 * Ignore invalid indexes, since they can't safely be used for
-			 * queries.  Note that this is OK because the data structure we
-			 * are constructing is only used by the planner --- the executor
-			 * still needs to insert into "invalid" indexes, if they're marked
-			 * indisready.
+			 * Skip invalid indexes, and invisible indexes unless
+			 * use_invisible_index is set. This is OK because the data
+			 * structure we are constructing is only used by the planner - the
+			 * executor still needs to insert into these indexes if they're
+			 * marked indisready.
 			 */
-			if (!index->indisvalid)
+			if (!index->indisvalid || (!index->indisvisible && !use_invisible_index))
 			{
 				index_close(indexRelation, NoLock);
 				continue;
@@ -2612,3 +2615,18 @@ set_baserel_partition_constraint(Relation relation, RelOptInfo *rel)
 		rel->partition_qual = partconstr;
 	}
 }
+
+/*
+ * assign_use_invisible_index
+ * GUC assign_hook for "use_invisible_index" GUC variable.
+ * Resets the plan cache when the value changes.
+ */
+void
+assign_use_invisible_index(bool newval, void *extra)
+{
+	if (use_invisible_index != newval)
+	{
+		use_invisible_index = newval;
+		ResetPlanCache();
+	}
+}
diff --git a/src/backend/parser/gram.y b/src/backend/parser/gram.y
index f1156e2fca..b5107cfbcb 100644
--- a/src/backend/parser/gram.y
+++ b/src/backend/parser/gram.y
@@ -324,7 +324,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 %type <ival>	add_drop opt_asc_desc opt_nulls_order
 
 %type <node>	alter_table_cmd alter_type_cmd opt_collate_clause
-	   replica_identity partition_cmd index_partition_cmd
+	   replica_identity partition_cmd index_partition_cmd index_alter_cmd
 %type <list>	alter_table_cmds alter_type_cmds
 %type <list>    alter_identity_column_option_list
 %type <defelt>  alter_identity_column_option
@@ -491,6 +491,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 %type <boolean> opt_unique opt_verbose opt_full
 %type <boolean> opt_freeze opt_analyze opt_default
 %type <defelt>	opt_binary copy_delimiter
+%type <boolean>  opt_index_visibility
 
 %type <boolean> copy_from opt_program
 
@@ -733,7 +734,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 	IDENTITY_P IF_P ILIKE IMMEDIATE IMMUTABLE IMPLICIT_P IMPORT_P IN_P INCLUDE
 	INCLUDING INCREMENT INDENT INDEX INDEXES INHERIT INHERITS INITIALLY INLINE_P
 	INNER_P INOUT INPUT_P INSENSITIVE INSERT INSTEAD INT_P INTEGER
-	INTERSECT INTERVAL INTO INVOKER IS ISNULL ISOLATION
+	INTERSECT INTERVAL INTO INVISIBLE INVOKER IS ISNULL ISOLATION
 
 	JOIN JSON JSON_ARRAY JSON_ARRAYAGG JSON_EXISTS JSON_OBJECT JSON_OBJECTAGG
 	JSON_QUERY JSON_SCALAR JSON_SERIALIZE JSON_TABLE JSON_VALUE
@@ -784,7 +785,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 	UNLISTEN UNLOGGED UNTIL UPDATE USER USING
 
 	VACUUM VALID VALIDATE VALIDATOR VALUE_P VALUES VARCHAR VARIADIC VARYING
-	VERBOSE VERSION_P VIEW VIEWS VIRTUAL VOLATILE
+	VERBOSE VERSION_P VIEW VIEWS VIRTUAL VISIBLE VOLATILE
 
 	WHEN WHERE WHITESPACE_P WINDOW WITH WITHIN WITHOUT WORK WRAPPER WRITE
 
@@ -2157,6 +2158,24 @@ AlterTableStmt:
 					n->nowait = $13;
 					$$ = (Node *) n;
 				}
+		| ALTER INDEX qualified_name index_alter_cmd
+				{
+					AlterTableStmt *n = makeNode(AlterTableStmt);
+					n->relation = $3;
+					n->cmds = list_make1($4);
+					n->objtype = OBJECT_INDEX;
+					n->missing_ok = false;
+					$$ = (Node *) n;
+				}
+		| ALTER INDEX IF_P EXISTS qualified_name index_alter_cmd
+				{
+					AlterTableStmt *n = makeNode(AlterTableStmt);
+					n->relation = $5;
+					n->cmds = list_make1($6);
+					n->objtype = OBJECT_INDEX;
+					n->missing_ok = true;
+					$$ = (Node *) n;
+				}
 		|	ALTER INDEX qualified_name alter_table_cmds
 				{
 					AlterTableStmt *n = makeNode(AlterTableStmt);
@@ -2382,6 +2401,21 @@ index_partition_cmd:
 				}
 		;
 
+index_alter_cmd:
+		/* ALTER INDEX <name> VISIBLE|INVISIBLE */
+		VISIBLE
+			{
+				AlterTableCmd *n = makeNode(AlterTableCmd);
+				n->subtype = AT_SetIndexVisible;
+				$$ = (Node *) n;
+			}
+		| INVISIBLE
+			{
+				AlterTableCmd *n = makeNode(AlterTableCmd);
+				n->subtype = AT_SetIndexInvisible;
+				$$ = (Node *) n;
+			}
+		;
 alter_table_cmd:
 			/* ALTER TABLE <name> ADD <coldef> */
 			ADD_P columnDef
@@ -8191,7 +8225,7 @@ defacl_privilege_target:
 
 IndexStmt:	CREATE opt_unique INDEX opt_concurrently opt_single_name
 			ON relation_expr access_method_clause '(' index_params ')'
-			opt_include opt_unique_null_treatment opt_reloptions OptTableSpace where_clause
+			opt_include opt_unique_null_treatment opt_reloptions OptTableSpace where_clause opt_index_visibility
 				{
 					IndexStmt *n = makeNode(IndexStmt);
 
@@ -8206,6 +8240,7 @@ IndexStmt:	CREATE opt_unique INDEX opt_concurrently opt_single_name
 					n->options = $14;
 					n->tableSpace = $15;
 					n->whereClause = $16;
+					n->isvisible = $17;
 					n->excludeOpNames = NIL;
 					n->idxcomment = NULL;
 					n->indexOid = InvalidOid;
@@ -8223,7 +8258,7 @@ IndexStmt:	CREATE opt_unique INDEX opt_concurrently opt_single_name
 				}
 			| CREATE opt_unique INDEX opt_concurrently IF_P NOT EXISTS name
 			ON relation_expr access_method_clause '(' index_params ')'
-			opt_include opt_unique_null_treatment opt_reloptions OptTableSpace where_clause
+			opt_include opt_unique_null_treatment opt_reloptions OptTableSpace where_clause opt_index_visibility
 				{
 					IndexStmt *n = makeNode(IndexStmt);
 
@@ -8238,6 +8273,7 @@ IndexStmt:	CREATE opt_unique INDEX opt_concurrently opt_single_name
 					n->options = $17;
 					n->tableSpace = $18;
 					n->whereClause = $19;
+					n->isvisible = $20;
 					n->excludeOpNames = NIL;
 					n->idxcomment = NULL;
 					n->indexOid = InvalidOid;
@@ -8260,6 +8296,12 @@ opt_unique:
 			| /*EMPTY*/								{ $$ = false; }
 		;
 
+opt_index_visibility:
+			VISIBLE                       { $$ = true; }
+			| INVISIBLE                   { $$ = false; }
+			| /*EMPTY*/                   { $$ = true; }
+		;
+
 access_method_clause:
 			USING name								{ $$ = $2; }
 			| /*EMPTY*/								{ $$ = DEFAULT_INDEX_TYPE; }
@@ -17837,6 +17879,7 @@ unreserved_keyword:
 			| INSENSITIVE
 			| INSERT
 			| INSTEAD
+			| INVISIBLE
 			| INVOKER
 			| ISOLATION
 			| KEEP
@@ -18023,6 +18066,7 @@ unreserved_keyword:
 			| VIEW
 			| VIEWS
 			| VIRTUAL
+			| VISIBLE
 			| VOLATILE
 			| WHITESPACE_P
 			| WITHIN
@@ -18432,6 +18476,7 @@ bare_label_keyword:
 			| INT_P
 			| INTEGER
 			| INTERVAL
+			| INVISIBLE
 			| INVOKER
 			| IS
 			| ISOLATION
@@ -18680,6 +18725,7 @@ bare_label_keyword:
 			| VIEW
 			| VIEWS
 			| VIRTUAL
+			| VISIBLE
 			| VOLATILE
 			| WHEN
 			| WHITESPACE_P
diff --git a/src/backend/parser/parse_utilcmd.c b/src/backend/parser/parse_utilcmd.c
index 62015431fd..0619833c09 100644
--- a/src/backend/parser/parse_utilcmd.c
+++ b/src/backend/parser/parse_utilcmd.c
@@ -1745,6 +1745,7 @@ generateClonedIndexStmt(RangeVar *heapRel, Relation source_idx,
 	index->concurrent = false;
 	index->if_not_exists = false;
 	index->reset_default_tblspc = false;
+	index->isvisible = idxrec->indisvisible;
 
 	/*
 	 * We don't try to preserve the name of the source index; instead, just
@@ -2366,6 +2367,8 @@ transformIndexConstraint(Constraint *constraint, CreateStmtContext *cxt)
 	index->concurrent = false;
 	index->if_not_exists = false;
 	index->reset_default_tblspc = constraint->reset_default_tblspc;
+	/* Ensure indexes for constraints are created as visible by default */
+	index->isvisible = true;
 
 	/*
 	 * If it's ALTER TABLE ADD CONSTRAINT USING INDEX, look up the index and
diff --git a/src/backend/utils/adt/ruleutils.c b/src/backend/utils/adt/ruleutils.c
index 9e90acedb9..199781c1ab 100644
--- a/src/backend/utils/adt/ruleutils.c
+++ b/src/backend/utils/adt/ruleutils.c
@@ -1565,6 +1565,10 @@ pg_get_indexdef_worker(Oid indexrelid, int colno,
 			else
 				appendStringInfo(&buf, " WHERE %s", str);
 		}
+
+		/* Add INVISIBLE clause if the index is invisible */
+		if (!idxrec->indisvisible)
+			appendStringInfoString(&buf, " INVISIBLE");
 	}
 
 	/* Clean up */
diff --git a/src/backend/utils/cache/relcache.c b/src/backend/utils/cache/relcache.c
index 18a14ae186..7f8078d491 100644
--- a/src/backend/utils/cache/relcache.c
+++ b/src/backend/utils/cache/relcache.c
@@ -2318,6 +2318,7 @@ RelationReloadIndexInfo(Relation relation)
 		relation->rd_index->indisready = index->indisready;
 		relation->rd_index->indislive = index->indislive;
 		relation->rd_index->indisreplident = index->indisreplident;
+		relation->rd_index->indisvisible = index->indisvisible;
 
 		/* Copy xmin too, as that is needed to make sense of indcheckxmin */
 		HeapTupleHeaderSetXmin(relation->rd_indextuple->t_data,
diff --git a/src/backend/utils/misc/guc_tables.c b/src/backend/utils/misc/guc_tables.c
index 4eaeca89f2..fa5370089d 100644
--- a/src/backend/utils/misc/guc_tables.c
+++ b/src/backend/utils/misc/guc_tables.c
@@ -2130,6 +2130,16 @@ struct config_bool ConfigureNamesBool[] =
 		true,
 		NULL, NULL, NULL
 	},
+	{
+		{"use_invisible_index", PGC_USERSET, QUERY_TUNING_OTHER,
+			gettext_noop("Forces the planner to consider invisible indexes."),
+			NULL,
+			GUC_EXPLAIN
+		},
+		&use_invisible_index,
+		false,
+		NULL, assign_use_invisible_index, NULL
+	},
 
 	/* End-of-list marker */
 	{
diff --git a/src/backend/utils/misc/postgresql.conf.sample b/src/backend/utils/misc/postgresql.conf.sample
index ff56a1f073..aa102ceffb 100644
--- a/src/backend/utils/misc/postgresql.conf.sample
+++ b/src/backend/utils/misc/postgresql.conf.sample
@@ -427,6 +427,7 @@
 #enable_tidscan = on
 #enable_group_by_reordering = on
 #enable_distinct_reordering = on
+#use_invisible_index = off		# forces planner to consider invisible indexes
 
 # - Planner Cost Constants -
 
diff --git a/src/bin/pg_dump/pg_dump.c b/src/bin/pg_dump/pg_dump.c
index 8e6364d32d..69de33f5dd 100644
--- a/src/bin/pg_dump/pg_dump.c
+++ b/src/bin/pg_dump/pg_dump.c
@@ -7645,7 +7645,8 @@ getIndexes(Archive *fout, TableInfo tblinfo[], int numTables)
 				i_tablespace,
 				i_indreloptions,
 				i_indstatcols,
-				i_indstatvals;
+				i_indstatvals,
+				i_indisvisible;
 
 	/*
 	 * We want to perform just one query against pg_index.  However, we
@@ -7688,7 +7689,7 @@ getIndexes(Archive *fout, TableInfo tblinfo[], int numTables)
 
 	appendPQExpBufferStr(query,
 						 "pg_catalog.pg_get_indexdef(i.indexrelid) AS indexdef, "
-						 "i.indkey, i.indisclustered, "
+						 "i.indkey, i.indisclustered, i.indisvisible, "
 						 "c.contype, c.conname, "
 						 "c.condeferrable, c.condeferred, "
 						 "c.tableoid AS contableoid, "
@@ -7710,6 +7711,13 @@ getIndexes(Archive *fout, TableInfo tblinfo[], int numTables)
 		appendPQExpBufferStr(query,
 							 "false AS indisreplident, ");
 
+	if (fout->remoteVersion >= 180000)
+		appendPQExpBufferStr(query,
+							 "i.indisvisible, ");
+	else
+		appendPQExpBufferStr(query,
+							 "true AS indisvisible, ");
+
 	if (fout->remoteVersion >= 110000)
 		appendPQExpBufferStr(query,
 							 "inh.inhparent AS parentidx, "
@@ -7824,6 +7832,7 @@ getIndexes(Archive *fout, TableInfo tblinfo[], int numTables)
 	i_indreloptions = PQfnumber(res, "indreloptions");
 	i_indstatcols = PQfnumber(res, "indstatcols");
 	i_indstatvals = PQfnumber(res, "indstatvals");
+	i_indisvisible = PQfnumber(res, "indisvisible");
 
 	indxinfo = (IndxInfo *) pg_malloc(ntups * sizeof(IndxInfo));
 
@@ -7914,7 +7923,7 @@ getIndexes(Archive *fout, TableInfo tblinfo[], int numTables)
 								  &indAttNames, &nindAttNames))
 					pg_fatal("could not parse %s array", "indattnames");
 			}
-
+			indxinfo[j].indisvisible = (PQgetvalue(res, j, i_indisvisible)[0] == 't');
 			relstats = getRelationStatistics(fout, &indxinfo[j].dobj, relpages,
 											 PQgetvalue(res, j, i_reltuples),
 											 relallvisible, relallfrozen, indexkind,
@@ -18062,6 +18071,12 @@ dumpConstraint(Archive *fout, const ConstraintInfo *coninfo)
 			}
 
 			appendPQExpBufferStr(q, ";\n");
+
+			if (!indxinfo->indisvisible)
+			{
+				appendPQExpBuffer(q, "ALTER INDEX %s INVISIBLE;\n",
+								  fmtQualifiedDumpable(indxinfo));
+			}
 		}
 
 		/*
diff --git a/src/bin/pg_dump/pg_dump.h b/src/bin/pg_dump/pg_dump.h
index e6f0f86a45..bf6b655780 100644
--- a/src/bin/pg_dump/pg_dump.h
+++ b/src/bin/pg_dump/pg_dump.h
@@ -427,6 +427,8 @@ typedef struct _indxInfo
 
 	/* if there is an associated constraint object, its dumpId: */
 	DumpId		indexconstraint;
+
+	bool		indisvisible;
 } IndxInfo;
 
 typedef struct _indexAttachInfo
diff --git a/src/bin/pg_dump/t/002_pg_dump.pl b/src/bin/pg_dump/t/002_pg_dump.pl
index 576326daec..d61d5c15f0 100644
--- a/src/bin/pg_dump/t/002_pg_dump.pl
+++ b/src/bin/pg_dump/t/002_pg_dump.pl
@@ -2168,6 +2168,35 @@ my %tests = (
 		like => {},
 	},
 
+	'ALTER TABLE ONLY test_table ADD CONSTRAINT ... PRIMARY KEY INVISIBLE' => {
+		create_order => 97,
+		create_sql => 'CREATE TABLE dump_test.test_table_invisible (
+					   id int PRIMARY KEY
+					  );
+					  ALTER INDEX dump_test.test_table_invisible_pkey INVISIBLE;',
+		regexp => qr/^
+			\QALTER TABLE ONLY dump_test.test_table_invisible\E\n\s+
+			\QADD CONSTRAINT test_table_invisible_pkey PRIMARY KEY (id);\E\n
+			\QALTER INDEX dump_test.test_table_invisible_pkey INVISIBLE;\E
+			/xm,
+		like => { %full_runs, %dump_test_schema_runs, section_post_data => 1 },
+		unlike => { exclude_dump_test_schema => 1, only_dump_measurement => 1 },
+	},
+
+	'CREATE INDEX ... INVISIBLE' => {
+		create_order => 98,
+		create_sql => 'CREATE TABLE dump_test.test_table_mixed_indexes (
+					   id int,
+					   value int
+					  );
+					  CREATE INDEX idx_visible ON dump_test.test_table_mixed_indexes(value);
+					  CREATE UNIQUE INDEX idx_invisible ON dump_test.test_table_mixed_indexes(value) INVISIBLE;
+					  ALTER INDEX dump_test.idx_invisible INVISIBLE;',
+		regexp => qr/CREATE UNIQUE INDEX idx_invisible ON dump_test\.test_table_mixed_indexes USING btree \(value\) INVISIBLE;/m,
+		like => { %full_runs, %dump_test_schema_runs, section_post_data => 1 },
+		unlike => { exclude_dump_test_schema => 1, only_dump_measurement => 1 },
+	},
+
 	'CREATE AGGREGATE dump_test.newavg' => {
 		create_order => 25,
 		create_sql => 'CREATE AGGREGATE dump_test.newavg (
diff --git a/src/bin/psql/describe.c b/src/bin/psql/describe.c
index 8970677ac6..dd2cb3e531 100644
--- a/src/bin/psql/describe.c
+++ b/src/bin/psql/describe.c
@@ -2329,6 +2329,11 @@ describeOneTableDetails(const char *schemaname,
 		else
 			appendPQExpBufferStr(&buf, "false AS indnullsnotdistinct,\n");
 
+		if (pset.sversion >= 180000)
+			appendPQExpBufferStr(&buf, "i.indisvisible,\n");
+		else
+			appendPQExpBufferStr(&buf, "true AS indisvisible,\n");
+
 		appendPQExpBuffer(&buf, "  a.amname, c2.relname, "
 						  "pg_catalog.pg_get_expr(i.indpred, i.indrelid, true)\n"
 						  "FROM pg_catalog.pg_index i, pg_catalog.pg_class c, pg_catalog.pg_class c2, pg_catalog.pg_am a\n"
@@ -2354,9 +2359,10 @@ describeOneTableDetails(const char *schemaname,
 			char	   *deferred = PQgetvalue(result, 0, 5);
 			char	   *indisreplident = PQgetvalue(result, 0, 6);
 			char	   *indnullsnotdistinct = PQgetvalue(result, 0, 7);
-			char	   *indamname = PQgetvalue(result, 0, 8);
-			char	   *indtable = PQgetvalue(result, 0, 9);
-			char	   *indpred = PQgetvalue(result, 0, 10);
+			char	   *indisvisible = PQgetvalue(result, 0, 8);
+			char	   *indamname = PQgetvalue(result, 0, 9);
+			char	   *indtable = PQgetvalue(result, 0, 10);
+			char	   *indpred = PQgetvalue(result, 0, 11);
 
 			if (strcmp(indisprimary, "t") == 0)
 				printfPQExpBuffer(&tmpbuf, _("primary key, "));
@@ -2393,6 +2399,9 @@ describeOneTableDetails(const char *schemaname,
 			if (strcmp(indisreplident, "t") == 0)
 				appendPQExpBufferStr(&tmpbuf, _(", replica identity"));
 
+			if (strcmp(indisvisible, "t") != 0)
+				appendPQExpBufferStr(&tmpbuf, _(", invisible"));
+
 			printTableAddFooter(&cont, tmpbuf.data);
 
 			/*
diff --git a/src/bin/psql/tab-complete.in.c b/src/bin/psql/tab-complete.in.c
index c916b9299a..8e2eb50205 100644
--- a/src/bin/psql/tab-complete.in.c
+++ b/src/bin/psql/tab-complete.in.c
@@ -2419,7 +2419,8 @@ match_previous_words(int pattern_id,
 	else if (Matches("ALTER", "INDEX", MatchAny))
 		COMPLETE_WITH("ALTER COLUMN", "OWNER TO", "RENAME TO", "SET",
 					  "RESET", "ATTACH PARTITION",
-					  "DEPENDS ON EXTENSION", "NO DEPENDS ON EXTENSION");
+					  "DEPENDS ON EXTENSION", "NO DEPENDS ON EXTENSION",
+					  "INVISIBLE", "VISIBLE");
 	else if (Matches("ALTER", "INDEX", MatchAny, "ATTACH"))
 		COMPLETE_WITH("PARTITION");
 	else if (Matches("ALTER", "INDEX", MatchAny, "ATTACH", "PARTITION"))
diff --git a/src/include/catalog/index.h b/src/include/catalog/index.h
index 4daa8bef5e..75bef5bd88 100644
--- a/src/include/catalog/index.h
+++ b/src/include/catalog/index.h
@@ -65,6 +65,7 @@ extern void index_check_primary_key(Relation heapRel,
 #define	INDEX_CREATE_IF_NOT_EXISTS			(1 << 4)
 #define	INDEX_CREATE_PARTITIONED			(1 << 5)
 #define INDEX_CREATE_INVALID				(1 << 6)
+#define INDEX_CREATE_VISIBLE				(1 << 7)
 
 extern Oid	index_create(Relation heapRelation,
 						 const char *indexRelationName,
@@ -175,7 +176,6 @@ extern void RestoreReindexState(const void *reindexstate);
 
 extern void IndexSetParentIndex(Relation partitionIdx, Oid parentOid);
 
-
 /*
  * itemptr_encode - Encode ItemPointer as int64/int8
  *
diff --git a/src/include/catalog/pg_index.h b/src/include/catalog/pg_index.h
index 4392b9d221..ec8e5dc4bf 100644
--- a/src/include/catalog/pg_index.h
+++ b/src/include/catalog/pg_index.h
@@ -44,6 +44,8 @@ CATALOG(pg_index,2610,IndexRelationId) BKI_SCHEMA_MACRO
 	bool		indisready;		/* is this index ready for inserts? */
 	bool		indislive;		/* is this index alive at all? */
 	bool		indisreplident; /* is this index the identity for replication? */
+	bool		indisvisible BKI_DEFAULT(t);	/* is this index visible for
+												 * use by queries? */
 
 	/* variable-length fields start here, but we allow direct access to indkey */
 	int2vector	indkey BKI_FORCE_NOT_NULL;	/* column numbers of indexed cols,
diff --git a/src/include/nodes/parsenodes.h b/src/include/nodes/parsenodes.h
index 4610fc6129..92a14b82f5 100644
--- a/src/include/nodes/parsenodes.h
+++ b/src/include/nodes/parsenodes.h
@@ -2472,6 +2472,8 @@ typedef enum AlterTableType
 	AT_SetIdentity,				/* SET identity column options */
 	AT_DropIdentity,			/* DROP IDENTITY */
 	AT_ReAddStatistics,			/* internal to commands/tablecmds.c */
+	AT_SetIndexVisible,			/* Set INDEX visible */
+	AT_SetIndexInvisible,		/* Set INDEX invisible */
 } AlterTableType;
 
 typedef struct AlterTableCmd	/* one subcommand of an ALTER TABLE */
@@ -3470,6 +3472,8 @@ typedef struct IndexStmt
 	bool		if_not_exists;	/* just do nothing if index already exists? */
 	bool		reset_default_tblspc;	/* reset default_tablespace prior to
 										 * executing */
+	bool		isvisible;		/* true if VISIBLE (default), false if
+								 * INVISIBLE */
 } IndexStmt;
 
 /* ----------------------
diff --git a/src/include/optimizer/optimizer.h b/src/include/optimizer/optimizer.h
index 546828b54b..3b5ca55bae 100644
--- a/src/include/optimizer/optimizer.h
+++ b/src/include/optimizer/optimizer.h
@@ -212,4 +212,9 @@ extern List *pull_var_clause(Node *node, int flags);
 extern Node *flatten_join_alias_vars(PlannerInfo *root, Query *query, Node *node);
 extern Node *flatten_group_exprs(PlannerInfo *root, Query *query, Node *node);
 
+/*
+ * GUC to tell planner to consider invisible indexes.
+ */
+extern bool use_invisible_index;
+
 #endif							/* OPTIMIZER_H */
diff --git a/src/include/parser/kwlist.h b/src/include/parser/kwlist.h
index a4af3f717a..77da5117cb 100644
--- a/src/include/parser/kwlist.h
+++ b/src/include/parser/kwlist.h
@@ -229,6 +229,7 @@ PG_KEYWORD("integer", INTEGER, COL_NAME_KEYWORD, BARE_LABEL)
 PG_KEYWORD("intersect", INTERSECT, RESERVED_KEYWORD, AS_LABEL)
 PG_KEYWORD("interval", INTERVAL, COL_NAME_KEYWORD, BARE_LABEL)
 PG_KEYWORD("into", INTO, RESERVED_KEYWORD, AS_LABEL)
+PG_KEYWORD("invisible", INVISIBLE, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("invoker", INVOKER, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("is", IS, TYPE_FUNC_NAME_KEYWORD, BARE_LABEL)
 PG_KEYWORD("isnull", ISNULL, TYPE_FUNC_NAME_KEYWORD, AS_LABEL)
@@ -493,6 +494,7 @@ PG_KEYWORD("version", VERSION_P, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("view", VIEW, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("views", VIEWS, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("virtual", VIRTUAL, UNRESERVED_KEYWORD, BARE_LABEL)
+PG_KEYWORD("visible", VISIBLE, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("volatile", VOLATILE, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("when", WHEN, RESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("where", WHERE, RESERVED_KEYWORD, AS_LABEL)
diff --git a/src/include/utils/guc_hooks.h b/src/include/utils/guc_hooks.h
index 799fa7ace6..dd5128fd87 100644
--- a/src/include/utils/guc_hooks.h
+++ b/src/include/utils/guc_hooks.h
@@ -178,5 +178,6 @@ extern bool check_synchronized_standby_slots(char **newval, void **extra,
 extern void assign_synchronized_standby_slots(const char *newval, void *extra);
 extern bool check_idle_replication_slot_timeout(int *newval, void **extra,
 												GucSource source);
+extern void assign_use_invisible_index(bool newval, void *extra);
 
 #endif							/* GUC_HOOKS_H */
diff --git a/src/test/modules/test_ddl_deparse/Makefile b/src/test/modules/test_ddl_deparse/Makefile
index 3a57a95c84..747d8b5835 100644
--- a/src/test/modules/test_ddl_deparse/Makefile
+++ b/src/test/modules/test_ddl_deparse/Makefile
@@ -27,7 +27,8 @@ REGRESS = test_ddl_deparse \
 	alter_type_enum \
 	opfamily \
 	defprivs \
-	matviews
+	matviews \
+	alter_index
 
 EXTRA_INSTALL = contrib/pg_stat_statements
 
diff --git a/src/test/modules/test_ddl_deparse/expected/alter_index.out b/src/test/modules/test_ddl_deparse/expected/alter_index.out
new file mode 100644
index 0000000000..f502baf1c5
--- /dev/null
+++ b/src/test/modules/test_ddl_deparse/expected/alter_index.out
@@ -0,0 +1,29 @@
+-- Test index visibility commands
+CREATE TABLE visibility_test (id int);
+NOTICE:  DDL test: type simple, tag CREATE TABLE
+CREATE INDEX idx_vis ON visibility_test(id);
+NOTICE:  DDL test: type simple, tag CREATE INDEX
+ALTER INDEX idx_vis INVISIBLE;
+NOTICE:  DDL test: type alter table, tag ALTER INDEX
+NOTICE:    subcommand: type SET INVISIBLE desc <NULL>
+ALTER INDEX idx_vis VISIBLE;
+NOTICE:  DDL test: type alter table, tag ALTER INDEX
+NOTICE:    subcommand: type SET VISIBLE desc <NULL>
+ALTER INDEX idx_vis INVISIBLE;
+NOTICE:  DDL test: type alter table, tag ALTER INDEX
+NOTICE:    subcommand: type SET INVISIBLE desc <NULL>
+REINDEX INDEX idx_vis;
+NOTICE:  DDL test: type simple, tag REINDEX
+CREATE SCHEMA visibility_schema;
+NOTICE:  DDL test: type simple, tag CREATE SCHEMA
+CREATE TABLE visibility_schema.test2 (id int);
+NOTICE:  DDL test: type simple, tag CREATE TABLE
+CREATE INDEX idx_vis2 ON visibility_schema.test2(id);
+NOTICE:  DDL test: type simple, tag CREATE INDEX
+ALTER INDEX visibility_schema.idx_vis2 INVISIBLE;
+NOTICE:  DDL test: type alter table, tag ALTER INDEX
+NOTICE:    subcommand: type SET INVISIBLE desc <NULL>
+-- Clean up
+DROP SCHEMA visibility_schema CASCADE;
+NOTICE:  drop cascades to table visibility_schema.test2
+DROP TABLE visibility_test CASCADE;
diff --git a/src/test/modules/test_ddl_deparse/meson.build b/src/test/modules/test_ddl_deparse/meson.build
index bff65ba633..6654b5e46d 100644
--- a/src/test/modules/test_ddl_deparse/meson.build
+++ b/src/test/modules/test_ddl_deparse/meson.build
@@ -48,6 +48,7 @@ tests += {
       'opfamily',
       'defprivs',
       'matviews',
+      'alter_index',
     ],
   },
 }
diff --git a/src/test/modules/test_ddl_deparse/sql/alter_index.sql b/src/test/modules/test_ddl_deparse/sql/alter_index.sql
new file mode 100644
index 0000000000..7a34dc6692
--- /dev/null
+++ b/src/test/modules/test_ddl_deparse/sql/alter_index.sql
@@ -0,0 +1,18 @@
+-- Test index visibility commands
+CREATE TABLE visibility_test (id int);
+CREATE INDEX idx_vis ON visibility_test(id);
+
+ALTER INDEX idx_vis INVISIBLE;
+ALTER INDEX idx_vis VISIBLE;
+
+ALTER INDEX idx_vis INVISIBLE;
+REINDEX INDEX idx_vis;
+
+CREATE SCHEMA visibility_schema;
+CREATE TABLE visibility_schema.test2 (id int);
+CREATE INDEX idx_vis2 ON visibility_schema.test2(id);
+ALTER INDEX visibility_schema.idx_vis2 INVISIBLE;
+
+-- Clean up
+DROP SCHEMA visibility_schema CASCADE;
+DROP TABLE visibility_test CASCADE;
diff --git a/src/test/modules/test_ddl_deparse/test_ddl_deparse.c b/src/test/modules/test_ddl_deparse/test_ddl_deparse.c
index 193669f2bc..8d7c7e5894 100644
--- a/src/test/modules/test_ddl_deparse/test_ddl_deparse.c
+++ b/src/test/modules/test_ddl_deparse/test_ddl_deparse.c
@@ -308,6 +308,12 @@ get_altertable_subcmdinfo(PG_FUNCTION_ARGS)
 			case AT_ReAddStatistics:
 				strtype = "(re) ADD STATS";
 				break;
+			case AT_SetIndexVisible:
+				strtype = "SET VISIBLE";
+				break;
+			case AT_SetIndexInvisible:
+				strtype = "SET INVISIBLE";
+				break;
 		}
 
 		if (subcmd->recurse)
diff --git a/src/test/regress/expected/create_index.out b/src/test/regress/expected/create_index.out
index 9ade7b835e..2ba2397a12 100644
--- a/src/test/regress/expected/create_index.out
+++ b/src/test/regress/expected/create_index.out
@@ -3542,6 +3542,801 @@ ERROR:  REINDEX SCHEMA cannot run inside a transaction block
 END;
 -- concurrently
 REINDEX SCHEMA CONCURRENTLY schema_to_reindex;
+-- Test index visibility functionality
+CREATE TABLE index_test(
+    id INT PRIMARY KEY,
+    data TEXT,
+    num INT,
+    vector INT[],
+    range INT4RANGE
+);
+INSERT INTO index_test
+SELECT
+    g,
+    'data ' || g,
+    g % 100,
+    ARRAY[g, g+1, g+2],
+    int4range(g, g+10)
+FROM generate_series(1, 1000) g;
+-- Function for testing
+CREATE FUNCTION get_data_length(text) RETURNS INT AS $$
+    SELECT length($1);
+$$ LANGUAGE SQL IMMUTABLE;
+-- Helper function to show index status
+CREATE OR REPLACE FUNCTION show_index_status(index_name text)
+RETURNS TABLE (
+    indexrelid regclass,
+    indisvalid boolean,
+    indisready boolean,
+    indislive boolean,
+    indisvisible boolean
+) AS $$
+BEGIN
+    RETURN QUERY EXECUTE format('
+        SELECT indexrelid::regclass, indisvalid, indisready, indislive, indisvisible
+        FROM pg_index
+        WHERE indexrelid = %L::regclass', index_name);
+END;
+$$ LANGUAGE plpgsql;
+-- Create and test each index type
+-- 1. Basic single-column index
+CREATE INDEX idx_single ON index_test(data);
+SELECT show_index_status('idx_single');
+  show_index_status   
+----------------------
+ (idx_single,t,t,t,t)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE data = 'data 500';
+                  QUERY PLAN                   
+-----------------------------------------------
+ Bitmap Heap Scan on index_test
+   Recheck Cond: (data = 'data 500'::text)
+   ->  Bitmap Index Scan on idx_single
+         Index Cond: (data = 'data 500'::text)
+(4 rows)
+
+ALTER INDEX idx_single INVISIBLE;
+SELECT show_index_status('idx_single');
+  show_index_status   
+----------------------
+ (idx_single,t,t,t,f)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE data = 'data 500';
+             QUERY PLAN              
+-------------------------------------
+ Seq Scan on index_test
+   Filter: (data = 'data 500'::text)
+(2 rows)
+
+ALTER INDEX idx_single VISIBLE;
+SELECT show_index_status('idx_single');
+  show_index_status   
+----------------------
+ (idx_single,t,t,t,t)
+(1 row)
+
+-- 2. Multi-column index
+CREATE INDEX idx_multi ON index_test(num, data);
+SELECT show_index_status('idx_multi');
+  show_index_status  
+---------------------
+ (idx_multi,t,t,t,t)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE num = 50 AND data > 'data 500';
+                           QUERY PLAN                           
+----------------------------------------------------------------
+ Bitmap Heap Scan on index_test
+   Recheck Cond: ((num = 50) AND (data > 'data 500'::text))
+   ->  Bitmap Index Scan on idx_multi
+         Index Cond: ((num = 50) AND (data > 'data 500'::text))
+(4 rows)
+
+ALTER INDEX idx_multi INVISIBLE;
+SELECT show_index_status('idx_multi');
+  show_index_status  
+---------------------
+ (idx_multi,t,t,t,f)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE num = 50 AND data > 'data 500';
+                      QUERY PLAN                      
+------------------------------------------------------
+ Seq Scan on index_test
+   Filter: ((data > 'data 500'::text) AND (num = 50))
+(2 rows)
+
+ALTER INDEX idx_multi VISIBLE;
+SELECT show_index_status('idx_multi');
+  show_index_status  
+---------------------
+ (idx_multi,t,t,t,t)
+(1 row)
+
+-- 3. Partial index
+CREATE INDEX idx_partial ON index_test(num) WHERE num < 50;
+SELECT show_index_status('idx_partial');
+   show_index_status   
+-----------------------
+ (idx_partial,t,t,t,t)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE num = 25;
+               QUERY PLAN               
+----------------------------------------
+ Bitmap Heap Scan on index_test
+   Recheck Cond: (num = 25)
+   ->  Bitmap Index Scan on idx_partial
+         Index Cond: (num = 25)
+(4 rows)
+
+ALTER INDEX idx_partial INVISIBLE;
+SELECT show_index_status('idx_partial');
+   show_index_status   
+-----------------------
+ (idx_partial,t,t,t,f)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE num = 25;
+              QUERY PLAN              
+--------------------------------------
+ Bitmap Heap Scan on index_test
+   Recheck Cond: (num = 25)
+   ->  Bitmap Index Scan on idx_multi
+         Index Cond: (num = 25)
+(4 rows)
+
+ALTER INDEX idx_partial VISIBLE;
+SELECT show_index_status('idx_partial');
+   show_index_status   
+-----------------------
+ (idx_partial,t,t,t,t)
+(1 row)
+
+-- 4. Expression index
+CREATE INDEX idx_expression ON index_test((lower(data)));
+SELECT show_index_status('idx_expression');
+    show_index_status     
+--------------------------
+ (idx_expression,t,t,t,t)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE lower(data) = 'data 500';
+                      QUERY PLAN                      
+------------------------------------------------------
+ Bitmap Heap Scan on index_test
+   Recheck Cond: (lower(data) = 'data 500'::text)
+   ->  Bitmap Index Scan on idx_expression
+         Index Cond: (lower(data) = 'data 500'::text)
+(4 rows)
+
+ALTER INDEX idx_expression INVISIBLE;
+SELECT show_index_status('idx_expression');
+    show_index_status     
+--------------------------
+ (idx_expression,t,t,t,f)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE lower(data) = 'data 500';
+                 QUERY PLAN                 
+--------------------------------------------
+ Seq Scan on index_test
+   Filter: (lower(data) = 'data 500'::text)
+(2 rows)
+
+ALTER INDEX idx_expression VISIBLE;
+SELECT show_index_status('idx_expression');
+    show_index_status     
+--------------------------
+ (idx_expression,t,t,t,t)
+(1 row)
+
+-- 5. GIN index
+CREATE INDEX idx_gin ON index_test USING gin(vector);
+SELECT show_index_status('idx_gin');
+ show_index_status 
+-------------------
+ (idx_gin,t,t,t,t)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE vector @> ARRAY[500];
+                     QUERY PLAN                     
+----------------------------------------------------
+ Bitmap Heap Scan on index_test
+   Recheck Cond: (vector @> '{500}'::integer[])
+   ->  Bitmap Index Scan on idx_gin
+         Index Cond: (vector @> '{500}'::integer[])
+(4 rows)
+
+ALTER INDEX idx_gin INVISIBLE;
+SELECT show_index_status('idx_gin');
+ show_index_status 
+-------------------
+ (idx_gin,t,t,t,f)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE vector @> ARRAY[500];
+                QUERY PLAN                
+------------------------------------------
+ Seq Scan on index_test
+   Filter: (vector @> '{500}'::integer[])
+(2 rows)
+
+ALTER INDEX idx_gin VISIBLE;
+SELECT show_index_status('idx_gin');
+ show_index_status 
+-------------------
+ (idx_gin,t,t,t,t)
+(1 row)
+
+-- 6. GiST index
+CREATE INDEX idx_gist ON index_test USING gist(range);
+SELECT show_index_status('idx_gist');
+ show_index_status  
+--------------------
+ (idx_gist,t,t,t,t)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE range && int4range(100, 110);
+                      QUERY PLAN                       
+-------------------------------------------------------
+ Bitmap Heap Scan on index_test
+   Recheck Cond: (range && '[100,110)'::int4range)
+   ->  Bitmap Index Scan on idx_gist
+         Index Cond: (range && '[100,110)'::int4range)
+(4 rows)
+
+ALTER INDEX idx_gist INVISIBLE;
+SELECT show_index_status('idx_gist');
+ show_index_status  
+--------------------
+ (idx_gist,t,t,t,f)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE range && int4range(100, 110);
+                 QUERY PLAN                  
+---------------------------------------------
+ Seq Scan on index_test
+   Filter: (range && '[100,110)'::int4range)
+(2 rows)
+
+ALTER INDEX idx_gist VISIBLE;
+SELECT show_index_status('idx_gist');
+ show_index_status  
+--------------------
+ (idx_gist,t,t,t,t)
+(1 row)
+
+-- 7. Covering index
+CREATE INDEX idx_covering ON index_test(num) INCLUDE (data);
+SELECT show_index_status('idx_covering');
+   show_index_status    
+------------------------
+ (idx_covering,t,t,t,t)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT num, data FROM index_test WHERE num = 50;
+               QUERY PLAN                
+-----------------------------------------
+ Bitmap Heap Scan on index_test
+   Recheck Cond: (num = 50)
+   ->  Bitmap Index Scan on idx_covering
+         Index Cond: (num = 50)
+(4 rows)
+
+ALTER INDEX idx_covering INVISIBLE;
+SELECT show_index_status('idx_covering');
+   show_index_status    
+------------------------
+ (idx_covering,t,t,t,f)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT num, data FROM index_test WHERE num = 50;
+              QUERY PLAN              
+--------------------------------------
+ Bitmap Heap Scan on index_test
+   Recheck Cond: (num = 50)
+   ->  Bitmap Index Scan on idx_multi
+         Index Cond: (num = 50)
+(4 rows)
+
+ALTER INDEX idx_covering VISIBLE;
+SELECT show_index_status('idx_covering');
+   show_index_status    
+------------------------
+ (idx_covering,t,t,t,t)
+(1 row)
+
+-- 8. Unique index
+CREATE UNIQUE INDEX idx_unique ON index_test(id, data);
+SELECT show_index_status('idx_unique');
+  show_index_status   
+----------------------
+ (idx_unique,t,t,t,t)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE id = 500 AND data = 'data 500';
+                        QUERY PLAN                        
+----------------------------------------------------------
+ Index Scan using idx_unique on index_test
+   Index Cond: ((id = 500) AND (data = 'data 500'::text))
+(2 rows)
+
+ALTER INDEX idx_unique INVISIBLE;
+SELECT show_index_status('idx_unique');
+  show_index_status   
+----------------------
+ (idx_unique,t,t,t,f)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE id = 500 AND data = 'data 500';
+                   QUERY PLAN                   
+------------------------------------------------
+ Index Scan using index_test_pkey on index_test
+   Index Cond: (id = 500)
+   Filter: (data = 'data 500'::text)
+(3 rows)
+
+ALTER INDEX idx_unique VISIBLE;
+SELECT show_index_status('idx_unique');
+  show_index_status   
+----------------------
+ (idx_unique,t,t,t,t)
+(1 row)
+
+-- 9. Function-based index
+CREATE INDEX idx_func ON index_test(get_data_length(data));
+SELECT show_index_status('idx_func');
+ show_index_status  
+--------------------
+ (idx_func,t,t,t,t)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE get_data_length(data) = 10;
+               QUERY PLAN                
+-----------------------------------------
+ Bitmap Heap Scan on index_test
+   Recheck Cond: (length(data) = 10)
+   ->  Bitmap Index Scan on idx_func
+         Index Cond: (length(data) = 10)
+(4 rows)
+
+ALTER INDEX idx_func INVISIBLE;
+SELECT show_index_status('idx_func');
+ show_index_status  
+--------------------
+ (idx_func,t,t,t,f)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE get_data_length(data) = 10;
+          QUERY PLAN           
+-------------------------------
+ Seq Scan on index_test
+   Filter: (length(data) = 10)
+(2 rows)
+
+ALTER INDEX idx_func VISIBLE;
+SELECT show_index_status('idx_func');
+ show_index_status  
+--------------------
+ (idx_func,t,t,t,t)
+(1 row)
+
+-- 10. Join index
+CREATE TABLE join_test (id INT PRIMARY KEY, ref_id INT);
+INSERT INTO join_test SELECT g, g % 100 FROM generate_series(1, 1000) g;
+CREATE INDEX idx_join ON join_test(ref_id);
+SELECT show_index_status('idx_join');
+ show_index_status  
+--------------------
+ (idx_join,t,t,t,t)
+(1 row)
+
+EXPLAIN (COSTS OFF)
+SELECT jt.id, it.data
+FROM join_test jt
+JOIN index_test it ON jt.ref_id = it.num
+WHERE jt.id BETWEEN 100 AND 200;
+                          QUERY PLAN                           
+---------------------------------------------------------------
+ Hash Join
+   Hash Cond: (it.num = jt.ref_id)
+   ->  Seq Scan on index_test it
+   ->  Hash
+         ->  Bitmap Heap Scan on join_test jt
+               Recheck Cond: ((id >= 100) AND (id <= 200))
+               ->  Bitmap Index Scan on join_test_pkey
+                     Index Cond: ((id >= 100) AND (id <= 200))
+(8 rows)
+
+-- Set all indexes to invisible to force seq scan
+ALTER INDEX idx_join INVISIBLE;
+ALTER INDEX join_test_pkey INVISIBLE;
+SELECT show_index_status('idx_join');
+ show_index_status  
+--------------------
+ (idx_join,t,t,t,f)
+(1 row)
+
+SELECT show_index_status('join_test_pkey');
+    show_index_status     
+--------------------------
+ (join_test_pkey,t,t,t,f)
+(1 row)
+
+EXPLAIN (COSTS OFF)
+SELECT jt.id, it.data
+FROM join_test jt
+JOIN index_test it ON jt.ref_id = it.num
+WHERE jt.id BETWEEN 100 AND 200;
+                     QUERY PLAN                      
+-----------------------------------------------------
+ Hash Join
+   Hash Cond: (it.num = jt.ref_id)
+   ->  Seq Scan on index_test it
+   ->  Hash
+         ->  Seq Scan on join_test jt
+               Filter: ((id >= 100) AND (id <= 200))
+(6 rows)
+
+ALTER INDEX idx_join VISIBLE;
+ALTER INDEX join_test_pkey VISIBLE;
+SELECT show_index_status('idx_join');
+ show_index_status  
+--------------------
+ (idx_join,t,t,t,t)
+(1 row)
+
+SELECT show_index_status('join_test_pkey');
+    show_index_status     
+--------------------------
+ (join_test_pkey,t,t,t,t)
+(1 row)
+
+-- Test REINDEX CONCURRENTLY
+REINDEX INDEX CONCURRENTLY idx_join;
+SELECT show_index_status('idx_join');
+ show_index_status  
+--------------------
+ (idx_join,t,t,t,t)
+(1 row)
+
+ALTER INDEX idx_join INVISIBLE;
+SELECT show_index_status('idx_join');
+ show_index_status  
+--------------------
+ (idx_join,t,t,t,f)
+(1 row)
+
+REINDEX INDEX CONCURRENTLY idx_join;
+SELECT show_index_status('idx_join');
+ show_index_status  
+--------------------
+ (idx_join,t,t,t,f)
+(1 row)
+
+SELECT pg_get_indexdef('idx_join'::regclass);
+                                   pg_get_indexdef                                   
+-------------------------------------------------------------------------------------
+ CREATE INDEX idx_join ON schema_to_reindex.join_test USING btree (ref_id) INVISIBLE
+(1 row)
+
+ALTER INDEX idx_join VISIBLE;
+SELECT pg_get_indexdef('idx_join'::regclass);
+                              pg_get_indexdef                              
+---------------------------------------------------------------------------
+ CREATE INDEX idx_join ON schema_to_reindex.join_test USING btree (ref_id)
+(1 row)
+
+-- Test index visibility with indcheckxmin being true
+CREATE TABLE indcheckxmin_test(id int PRIMARY KEY);
+INSERT INTO indcheckxmin_test VALUES (1), (2), (3);
+CREATE INDEX CONCURRENTLY idx_checkxmin ON indcheckxmin_test(id);
+BEGIN;
+-- Simulate indcheckxmin being true
+UPDATE pg_index SET indcheckxmin = true WHERE indexrelid = 'idx_checkxmin'::regclass;
+ALTER INDEX idx_checkxmin INVISIBLE;  -- expect fail
+ERROR:  cannot update index visibility while indcheckxmin is true
+HINT:  Wait for all transactions that might see inconsistent HOT chains to complete
+ROLLBACK;
+-- Test prepared statements with index visibility
+CREATE TABLE prep_idx_test (id int, data text);
+CREATE INDEX prep_idx1 ON prep_idx_test(data);
+INSERT INTO prep_idx_test SELECT g, 'data ' || g FROM generate_series(1,100) g;
+-- Test with visible index
+PREPARE idx_plan AS SELECT * FROM prep_idx_test WHERE data = $1;
+EXPLAIN (COSTS OFF) EXECUTE idx_plan('data 1');
+                 QUERY PLAN                  
+---------------------------------------------
+ Bitmap Heap Scan on prep_idx_test
+   Recheck Cond: (data = 'data 1'::text)
+   ->  Bitmap Index Scan on prep_idx1
+         Index Cond: (data = 'data 1'::text)
+(4 rows)
+
+EXECUTE idx_plan('data 1');
+ id |  data  
+----+--------
+  1 | data 1
+(1 row)
+
+-- Test with invisible index
+ALTER INDEX prep_idx1 INVISIBLE;
+EXPLAIN (COSTS OFF) EXECUTE idx_plan('data 1');
+            QUERY PLAN             
+-----------------------------------
+ Seq Scan on prep_idx_test
+   Filter: (data = 'data 1'::text)
+(2 rows)
+
+EXECUTE idx_plan('data 1');
+ id |  data  
+----+--------
+  1 | data 1
+(1 row)
+
+-- Test with use_invisible_index
+SET use_invisible_index TO on;
+EXPLAIN (COSTS OFF) EXECUTE idx_plan('data 1');
+                 QUERY PLAN                  
+---------------------------------------------
+ Bitmap Heap Scan on prep_idx_test
+   Recheck Cond: (data = 'data 1'::text)
+   ->  Bitmap Index Scan on prep_idx1
+         Index Cond: (data = 'data 1'::text)
+(4 rows)
+
+EXECUTE idx_plan('data 1');
+ id |  data  
+----+--------
+  1 | data 1
+(1 row)
+
+SET use_invisible_index TO off;
+-- Assert plan cache is reset and index is not used
+EXPLAIN (COSTS OFF) EXECUTE idx_plan('data 1');
+            QUERY PLAN             
+-----------------------------------
+ Seq Scan on prep_idx_test
+   Filter: (data = 'data 1'::text)
+(2 rows)
+
+-- Make index visible and test again
+ALTER INDEX prep_idx1 VISIBLE;
+EXPLAIN (COSTS OFF) EXECUTE idx_plan('data 1');
+                 QUERY PLAN                  
+---------------------------------------------
+ Bitmap Heap Scan on prep_idx_test
+   Recheck Cond: (data = 'data 1'::text)
+   ->  Bitmap Index Scan on prep_idx1
+         Index Cond: (data = 'data 1'::text)
+(4 rows)
+
+EXECUTE idx_plan('data 1');
+ id |  data  
+----+--------
+  1 | data 1
+(1 row)
+
+-- Test index visibility with partitioned tables
+CREATE TABLE part_tbl(id int, data text) PARTITION BY RANGE(id);
+CREATE TABLE part1 PARTITION OF part_tbl FOR VALUES FROM (1) TO (100);
+CREATE TABLE part2 PARTITION OF part_tbl FOR VALUES FROM (100) TO (200);
+INSERT INTO part_tbl
+SELECT g, 'data ' || g
+FROM generate_series(1, 199) g;
+CREATE INDEX idx_part_tbl ON part_tbl(data);
+SELECT c.relname, i.indisvisible
+FROM pg_index i
+JOIN pg_class c ON i.indexrelid = c.oid
+WHERE c.relname LIKE 'idx_part_tbl%'
+ORDER BY c.relname;
+   relname    | indisvisible 
+--------------+--------------
+ idx_part_tbl | t
+(1 row)
+
+-- Force use of indexes to avoid flaky test results
+SET enable_seqscan = off;
+EXPLAIN (COSTS OFF)
+SELECT * FROM part_tbl WHERE data = 'data 50';
+                        QUERY PLAN                         
+-----------------------------------------------------------
+ Append
+   ->  Index Scan using part1_data_idx on part1 part_tbl_1
+         Index Cond: (data = 'data 50'::text)
+   ->  Index Scan using part2_data_idx on part2 part_tbl_2
+         Index Cond: (data = 'data 50'::text)
+(5 rows)
+
+ALTER INDEX idx_part_tbl INVISIBLE;
+SELECT c.relname, i.indisvisible
+FROM pg_index i
+JOIN pg_class c ON i.indexrelid = c.oid
+WHERE c.relname LIKE 'idx_part_tbl%'
+ORDER BY c.relname;
+   relname    | indisvisible 
+--------------+--------------
+ idx_part_tbl | f
+(1 row)
+
+-- Check query plan after setting invisible (should use seq scan)
+EXPLAIN (COSTS OFF)
+SELECT * FROM part_tbl WHERE data = 'data 50';
+                QUERY PLAN                
+------------------------------------------
+ Append
+   ->  Seq Scan on part1 part_tbl_1
+         Disabled: true
+         Filter: (data = 'data 50'::text)
+   ->  Seq Scan on part2 part_tbl_2
+         Disabled: true
+         Filter: (data = 'data 50'::text)
+(7 rows)
+
+SET use_invisible_index TO on;
+EXPLAIN (COSTS OFF)
+SELECT * FROM part_tbl WHERE data = 'data 50';
+                        QUERY PLAN                         
+-----------------------------------------------------------
+ Append
+   ->  Index Scan using part1_data_idx on part1 part_tbl_1
+         Index Cond: (data = 'data 50'::text)
+   ->  Index Scan using part2_data_idx on part2 part_tbl_2
+         Index Cond: (data = 'data 50'::text)
+(5 rows)
+
+SET use_invisible_index TO off;
+EXPLAIN (COSTS OFF)
+SELECT * FROM part_tbl WHERE data = 'data 50';
+                QUERY PLAN                
+------------------------------------------
+ Append
+   ->  Seq Scan on part1 part_tbl_1
+         Disabled: true
+         Filter: (data = 'data 50'::text)
+   ->  Seq Scan on part2 part_tbl_2
+         Disabled: true
+         Filter: (data = 'data 50'::text)
+(7 rows)
+
+ALTER INDEX idx_part_tbl VISIBLE;
+SELECT c.relname, i.indisvisible
+FROM pg_index i
+JOIN pg_class c ON i.indexrelid = c.oid
+WHERE c.relname LIKE 'idx_part_tbl%'
+ORDER BY c.relname;
+   relname    | indisvisible 
+--------------+--------------
+ idx_part_tbl | t
+(1 row)
+
+EXPLAIN (COSTS OFF)
+SELECT * FROM part_tbl WHERE data = 'data 50';
+                        QUERY PLAN                         
+-----------------------------------------------------------
+ Append
+   ->  Index Scan using part1_data_idx on part1 part_tbl_1
+         Index Cond: (data = 'data 50'::text)
+   ->  Index Scan using part2_data_idx on part2 part_tbl_2
+         Index Cond: (data = 'data 50'::text)
+(5 rows)
+
+SET enable_seqscan = on;
+-- Test REINDEX maintains visibility setting
+ALTER INDEX idx_part_tbl INVISIBLE;
+REINDEX INDEX idx_part_tbl;
+SELECT c.relname, i.indisvisible
+FROM pg_index i
+JOIN pg_class c ON i.indexrelid = c.oid
+WHERE c.relname LIKE 'idx_part_tbl%'
+ORDER BY c.relname;
+   relname    | indisvisible 
+--------------+--------------
+ idx_part_tbl | f
+(1 row)
+
+-- Test that index visibility is preserved after ALTER TABLE
+CREATE TABLE vis_test(id INT PRIMARY KEY, data text);
+\d vis_test
+        Table "schema_to_reindex.vis_test"
+ Column |  Type   | Collation | Nullable | Default 
+--------+---------+-----------+----------+---------
+ id     | integer |           | not null | 
+ data   | text    |           |          | 
+Indexes:
+    "vis_test_pkey" PRIMARY KEY, btree (id)
+
+ALTER INDEX vis_test_pkey INVISIBLE;
+\d vis_test
+        Table "schema_to_reindex.vis_test"
+ Column |  Type   | Collation | Nullable | Default 
+--------+---------+-----------+----------+---------
+ id     | integer |           | not null | 
+ data   | text    |           |          | 
+Indexes:
+    "vis_test_pkey" PRIMARY KEY, btree (id) INVISIBLE
+
+ALTER TABLE vis_test ALTER COLUMN id SET DATA TYPE bigint;
+\d vis_test
+        Table "schema_to_reindex.vis_test"
+ Column |  Type  | Collation | Nullable | Default 
+--------+--------+-----------+----------+---------
+ id     | bigint |           | not null | 
+ data   | text   |           |          | 
+Indexes:
+    "vis_test_pkey" PRIMARY KEY, btree (id) INVISIBLE
+
+ALTER TABLE vis_test ALTER COLUMN id SET DATA TYPE int;
+\d vis_test
+        Table "schema_to_reindex.vis_test"
+ Column |  Type   | Collation | Nullable | Default 
+--------+---------+-----------+----------+---------
+ id     | integer |           | not null | 
+ data   | text    |           |          | 
+Indexes:
+    "vis_test_pkey" PRIMARY KEY, btree (id) INVISIBLE
+
+ALTER INDEX vis_test_pkey VISIBLE;
+\d vis_test
+        Table "schema_to_reindex.vis_test"
+ Column |  Type   | Collation | Nullable | Default 
+--------+---------+-----------+----------+---------
+ id     | integer |           | not null | 
+ data   | text    |           |          | 
+Indexes:
+    "vis_test_pkey" PRIMARY KEY, btree (id)
+
+-- Test CREATE INDEX with INVISIBLE option
+CREATE TABLE invis_test(id int, data text);
+INSERT INTO invis_test SELECT g, 'data ' || g FROM generate_series(1,100) g;
+CREATE INDEX idx_invis1 ON invis_test(data) INVISIBLE;
+\d invis_test
+       Table "schema_to_reindex.invis_test"
+ Column |  Type   | Collation | Nullable | Default 
+--------+---------+-----------+----------+---------
+ id     | integer |           |          | 
+ data   | text    |           |          | 
+Indexes:
+    "idx_invis1" btree (data) INVISIBLE
+
+\d idx_invis1
+Index "schema_to_reindex.idx_invis1"
+ Column | Type | Key? | Definition 
+--------+------+------+------------
+ data   | text | yes  | data
+btree, for table "schema_to_reindex.invis_test", invisible
+
+ALTER INDEX idx_invis1 VISIBLE;
+\d invis_test
+       Table "schema_to_reindex.invis_test"
+ Column |  Type   | Collation | Nullable | Default 
+--------+---------+-----------+----------+---------
+ id     | integer |           |          | 
+ data   | text    |           |          | 
+Indexes:
+    "idx_invis1" btree (data)
+
+\d idx_invis1
+Index "schema_to_reindex.idx_invis1"
+ Column | Type | Key? | Definition 
+--------+------+------+------------
+ data   | text | yes  | data
+btree, for table "schema_to_reindex.invis_test"
+
+-- Clean up
+DROP TABLE index_test;
+DROP TABLE join_test;
+DROP FUNCTION get_data_length;
+DROP FUNCTION show_index_status;
+DROP TABLE indcheckxmin_test CASCADE;
+DEALLOCATE idx_plan;
+DROP TABLE prep_idx_test;
+DROP TABLE part_tbl CASCADE;
+DROP TABLE vis_test;
+DROP TABLE invis_test;
 -- Failure for unauthorized user
 CREATE ROLE regress_reindexuser NOLOGIN;
 SET SESSION ROLE regress_reindexuser;
diff --git a/src/test/regress/sql/create_index.sql b/src/test/regress/sql/create_index.sql
index e21ff42651..b4bea3f9d9 100644
--- a/src/test/regress/sql/create_index.sql
+++ b/src/test/regress/sql/create_index.sql
@@ -1496,6 +1496,327 @@ END;
 -- concurrently
 REINDEX SCHEMA CONCURRENTLY schema_to_reindex;
 
+-- Test index visibility functionality
+
+CREATE TABLE index_test(
+    id INT PRIMARY KEY,
+    data TEXT,
+    num INT,
+    vector INT[],
+    range INT4RANGE
+);
+
+INSERT INTO index_test
+SELECT
+    g,
+    'data ' || g,
+    g % 100,
+    ARRAY[g, g+1, g+2],
+    int4range(g, g+10)
+FROM generate_series(1, 1000) g;
+
+-- Function for testing
+CREATE FUNCTION get_data_length(text) RETURNS INT AS $$
+    SELECT length($1);
+$$ LANGUAGE SQL IMMUTABLE;
+
+-- Helper function to show index status
+CREATE OR REPLACE FUNCTION show_index_status(index_name text)
+RETURNS TABLE (
+    indexrelid regclass,
+    indisvalid boolean,
+    indisready boolean,
+    indislive boolean,
+    indisvisible boolean
+) AS $$
+BEGIN
+    RETURN QUERY EXECUTE format('
+        SELECT indexrelid::regclass, indisvalid, indisready, indislive, indisvisible
+        FROM pg_index
+        WHERE indexrelid = %L::regclass', index_name);
+END;
+$$ LANGUAGE plpgsql;
+
+-- Create and test each index type
+-- 1. Basic single-column index
+CREATE INDEX idx_single ON index_test(data);
+SELECT show_index_status('idx_single');
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE data = 'data 500';
+ALTER INDEX idx_single INVISIBLE;
+SELECT show_index_status('idx_single');
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE data = 'data 500';
+ALTER INDEX idx_single VISIBLE;
+SELECT show_index_status('idx_single');
+
+-- 2. Multi-column index
+CREATE INDEX idx_multi ON index_test(num, data);
+SELECT show_index_status('idx_multi');
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE num = 50 AND data > 'data 500';
+ALTER INDEX idx_multi INVISIBLE;
+SELECT show_index_status('idx_multi');
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE num = 50 AND data > 'data 500';
+ALTER INDEX idx_multi VISIBLE;
+SELECT show_index_status('idx_multi');
+
+-- 3. Partial index
+CREATE INDEX idx_partial ON index_test(num) WHERE num < 50;
+SELECT show_index_status('idx_partial');
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE num = 25;
+ALTER INDEX idx_partial INVISIBLE;
+SELECT show_index_status('idx_partial');
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE num = 25;
+ALTER INDEX idx_partial VISIBLE;
+SELECT show_index_status('idx_partial');
+
+-- 4. Expression index
+CREATE INDEX idx_expression ON index_test((lower(data)));
+SELECT show_index_status('idx_expression');
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE lower(data) = 'data 500';
+ALTER INDEX idx_expression INVISIBLE;
+SELECT show_index_status('idx_expression');
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE lower(data) = 'data 500';
+ALTER INDEX idx_expression VISIBLE;
+SELECT show_index_status('idx_expression');
+
+-- 5. GIN index
+CREATE INDEX idx_gin ON index_test USING gin(vector);
+SELECT show_index_status('idx_gin');
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE vector @> ARRAY[500];
+ALTER INDEX idx_gin INVISIBLE;
+SELECT show_index_status('idx_gin');
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE vector @> ARRAY[500];
+ALTER INDEX idx_gin VISIBLE;
+SELECT show_index_status('idx_gin');
+
+-- 6. GiST index
+CREATE INDEX idx_gist ON index_test USING gist(range);
+SELECT show_index_status('idx_gist');
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE range && int4range(100, 110);
+ALTER INDEX idx_gist INVISIBLE;
+SELECT show_index_status('idx_gist');
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE range && int4range(100, 110);
+ALTER INDEX idx_gist VISIBLE;
+SELECT show_index_status('idx_gist');
+
+-- 7. Covering index
+CREATE INDEX idx_covering ON index_test(num) INCLUDE (data);
+SELECT show_index_status('idx_covering');
+EXPLAIN (COSTS OFF) SELECT num, data FROM index_test WHERE num = 50;
+ALTER INDEX idx_covering INVISIBLE;
+SELECT show_index_status('idx_covering');
+EXPLAIN (COSTS OFF) SELECT num, data FROM index_test WHERE num = 50;
+ALTER INDEX idx_covering VISIBLE;
+SELECT show_index_status('idx_covering');
+
+-- 8. Unique index
+CREATE UNIQUE INDEX idx_unique ON index_test(id, data);
+SELECT show_index_status('idx_unique');
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE id = 500 AND data = 'data 500';
+ALTER INDEX idx_unique INVISIBLE;
+SELECT show_index_status('idx_unique');
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE id = 500 AND data = 'data 500';
+ALTER INDEX idx_unique VISIBLE;
+SELECT show_index_status('idx_unique');
+
+-- 9. Function-based index
+CREATE INDEX idx_func ON index_test(get_data_length(data));
+SELECT show_index_status('idx_func');
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE get_data_length(data) = 10;
+ALTER INDEX idx_func INVISIBLE;
+SELECT show_index_status('idx_func');
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE get_data_length(data) = 10;
+ALTER INDEX idx_func VISIBLE;
+SELECT show_index_status('idx_func');
+
+-- 10. Join index
+CREATE TABLE join_test (id INT PRIMARY KEY, ref_id INT);
+INSERT INTO join_test SELECT g, g % 100 FROM generate_series(1, 1000) g;
+CREATE INDEX idx_join ON join_test(ref_id);
+SELECT show_index_status('idx_join');
+
+EXPLAIN (COSTS OFF)
+SELECT jt.id, it.data
+FROM join_test jt
+JOIN index_test it ON jt.ref_id = it.num
+WHERE jt.id BETWEEN 100 AND 200;
+
+-- Set all indexes to invisible to force seq scan
+ALTER INDEX idx_join INVISIBLE;
+ALTER INDEX join_test_pkey INVISIBLE;
+SELECT show_index_status('idx_join');
+SELECT show_index_status('join_test_pkey');
+
+EXPLAIN (COSTS OFF)
+SELECT jt.id, it.data
+FROM join_test jt
+JOIN index_test it ON jt.ref_id = it.num
+WHERE jt.id BETWEEN 100 AND 200;
+
+ALTER INDEX idx_join VISIBLE;
+ALTER INDEX join_test_pkey VISIBLE;
+SELECT show_index_status('idx_join');
+SELECT show_index_status('join_test_pkey');
+
+-- Test REINDEX CONCURRENTLY
+REINDEX INDEX CONCURRENTLY idx_join;
+SELECT show_index_status('idx_join');
+
+ALTER INDEX idx_join INVISIBLE;
+SELECT show_index_status('idx_join');
+REINDEX INDEX CONCURRENTLY idx_join;
+SELECT show_index_status('idx_join');
+
+SELECT pg_get_indexdef('idx_join'::regclass);
+ALTER INDEX idx_join VISIBLE;
+SELECT pg_get_indexdef('idx_join'::regclass);
+
+-- Test index visibility with indcheckxmin being true
+
+CREATE TABLE indcheckxmin_test(id int PRIMARY KEY);
+INSERT INTO indcheckxmin_test VALUES (1), (2), (3);
+CREATE INDEX CONCURRENTLY idx_checkxmin ON indcheckxmin_test(id);
+BEGIN;
+-- Simulate indcheckxmin being true
+UPDATE pg_index SET indcheckxmin = true WHERE indexrelid = 'idx_checkxmin'::regclass;
+ALTER INDEX idx_checkxmin INVISIBLE;  -- expect fail
+ROLLBACK;
+
+-- Test prepared statements with index visibility
+CREATE TABLE prep_idx_test (id int, data text);
+CREATE INDEX prep_idx1 ON prep_idx_test(data);
+INSERT INTO prep_idx_test SELECT g, 'data ' || g FROM generate_series(1,100) g;
+
+-- Test with visible index
+PREPARE idx_plan AS SELECT * FROM prep_idx_test WHERE data = $1;
+EXPLAIN (COSTS OFF) EXECUTE idx_plan('data 1');
+EXECUTE idx_plan('data 1');
+
+-- Test with invisible index
+ALTER INDEX prep_idx1 INVISIBLE;
+EXPLAIN (COSTS OFF) EXECUTE idx_plan('data 1');
+EXECUTE idx_plan('data 1');
+
+-- Test with use_invisible_index
+SET use_invisible_index TO on;
+EXPLAIN (COSTS OFF) EXECUTE idx_plan('data 1');
+EXECUTE idx_plan('data 1');
+SET use_invisible_index TO off;
+-- Assert plan cache is reset and index is not used
+EXPLAIN (COSTS OFF) EXECUTE idx_plan('data 1');
+
+-- Make index visible and test again
+ALTER INDEX prep_idx1 VISIBLE;
+EXPLAIN (COSTS OFF) EXECUTE idx_plan('data 1');
+EXECUTE idx_plan('data 1');
+
+-- Test index visibility with partitioned tables
+CREATE TABLE part_tbl(id int, data text) PARTITION BY RANGE(id);
+CREATE TABLE part1 PARTITION OF part_tbl FOR VALUES FROM (1) TO (100);
+CREATE TABLE part2 PARTITION OF part_tbl FOR VALUES FROM (100) TO (200);
+
+INSERT INTO part_tbl
+SELECT g, 'data ' || g
+FROM generate_series(1, 199) g;
+
+CREATE INDEX idx_part_tbl ON part_tbl(data);
+
+SELECT c.relname, i.indisvisible
+FROM pg_index i
+JOIN pg_class c ON i.indexrelid = c.oid
+WHERE c.relname LIKE 'idx_part_tbl%'
+ORDER BY c.relname;
+
+-- Force use of indexes to avoid flaky test results
+SET enable_seqscan = off;
+
+EXPLAIN (COSTS OFF)
+SELECT * FROM part_tbl WHERE data = 'data 50';
+
+ALTER INDEX idx_part_tbl INVISIBLE;
+
+SELECT c.relname, i.indisvisible
+FROM pg_index i
+JOIN pg_class c ON i.indexrelid = c.oid
+WHERE c.relname LIKE 'idx_part_tbl%'
+ORDER BY c.relname;
+
+-- Check query plan after setting invisible (should use seq scan)
+EXPLAIN (COSTS OFF)
+SELECT * FROM part_tbl WHERE data = 'data 50';
+
+SET use_invisible_index TO on;
+
+EXPLAIN (COSTS OFF)
+SELECT * FROM part_tbl WHERE data = 'data 50';
+
+SET use_invisible_index TO off;
+
+EXPLAIN (COSTS OFF)
+SELECT * FROM part_tbl WHERE data = 'data 50';
+
+ALTER INDEX idx_part_tbl VISIBLE;
+
+SELECT c.relname, i.indisvisible
+FROM pg_index i
+JOIN pg_class c ON i.indexrelid = c.oid
+WHERE c.relname LIKE 'idx_part_tbl%'
+ORDER BY c.relname;
+
+EXPLAIN (COSTS OFF)
+SELECT * FROM part_tbl WHERE data = 'data 50';
+
+SET enable_seqscan = on;
+
+-- Test REINDEX maintains visibility setting
+ALTER INDEX idx_part_tbl INVISIBLE;
+REINDEX INDEX idx_part_tbl;
+
+SELECT c.relname, i.indisvisible
+FROM pg_index i
+JOIN pg_class c ON i.indexrelid = c.oid
+WHERE c.relname LIKE 'idx_part_tbl%'
+ORDER BY c.relname;
+
+-- Test that index visibility is preserved after ALTER TABLE
+CREATE TABLE vis_test(id INT PRIMARY KEY, data text);
+\d vis_test
+
+ALTER INDEX vis_test_pkey INVISIBLE;
+\d vis_test
+
+ALTER TABLE vis_test ALTER COLUMN id SET DATA TYPE bigint;
+\d vis_test
+
+ALTER TABLE vis_test ALTER COLUMN id SET DATA TYPE int;
+\d vis_test
+
+ALTER INDEX vis_test_pkey VISIBLE;
+\d vis_test
+
+-- Test CREATE INDEX with INVISIBLE option
+CREATE TABLE invis_test(id int, data text);
+INSERT INTO invis_test SELECT g, 'data ' || g FROM generate_series(1,100) g;
+
+CREATE INDEX idx_invis1 ON invis_test(data) INVISIBLE;
+\d invis_test
+\d idx_invis1
+
+ALTER INDEX idx_invis1 VISIBLE;
+\d invis_test
+\d idx_invis1
+
+-- Clean up
+DROP TABLE index_test;
+DROP TABLE join_test;
+DROP FUNCTION get_data_length;
+DROP FUNCTION show_index_status;
+DROP TABLE indcheckxmin_test CASCADE;
+DEALLOCATE idx_plan;
+DROP TABLE prep_idx_test;
+DROP TABLE part_tbl CASCADE;
+DROP TABLE vis_test;
+DROP TABLE invis_test;
+
 -- Failure for unauthorized user
 CREATE ROLE regress_reindexuser NOLOGIN;
 SET SESSION ROLE regress_reindexuser;
-- 
2.39.5 (Apple Git-154)

#83Sami Imseih
samimseih@gmail.com
In reply to: Shayon Mukherjee (#82)
Re: [PATCH] Re: Proposal to Enable/Disable Index using ALTER INDEX

Thanks for the update!

The changes in v15 look good to me. The patch does need to be rebased,
and I also think you should add a tab-complete for CREATE INDEX

simseih@bcd07415af92 postgresql % git diff
diff --git a/src/bin/psql/tab-complete.in.c b/src/bin/psql/tab-complete.in.c
index 8e2eb50205e..f1853a68ccc 100644
--- a/src/bin/psql/tab-complete.in.c
+++ b/src/bin/psql/tab-complete.in.c
@@ -3434,6 +3434,8 @@ match_previous_words(int pattern_id,
                         !TailMatches("POLICY", MatchAny, MatchAny,
MatchAny, MatchAny, MatchAny) &&
                         !TailMatches("FOR", MatchAny, MatchAny, MatchAny))
                COMPLETE_WITH("(");
+       else if (TailMatches("*)"))
+               COMPLETE_WITH("VISIBLE", "INVISIBLE");

/* CREATE OR REPLACE */
else if (Matches("CREATE", "OR"))

IMO, with the above in place, this patch is RFC.

--
Sami Imseih
Amazon Web Services (AWS)

#84Shayon Mukherjee
shayonj@gmail.com
In reply to: Sami Imseih (#83)
1 attachment(s)
Re: [PATCH] Re: Proposal to Enable/Disable Index using ALTER INDEX

On Mon, Apr 7, 2025 at 4:01 PM Sami Imseih <samimseih@gmail.com> wrote:

Thanks for the update!

The changes in v15 look good to me. The patch does need to be rebased,
and I also think you should add a tab-complete for CREATE INDEX

simseih@bcd07415af92 postgresql % git diff
diff --git a/src/bin/psql/tab-complete.in.c
b/src/bin/psql/tab-complete.in.c
index 8e2eb50205e..f1853a68ccc 100644
--- a/src/bin/psql/tab-complete.in.c
+++ b/src/bin/psql/tab-complete.in.c
@@ -3434,6 +3434,8 @@ match_previous_words(int pattern_id,
!TailMatches("POLICY", MatchAny, MatchAny,
MatchAny, MatchAny, MatchAny) &&
!TailMatches("FOR", MatchAny, MatchAny, MatchAny))
COMPLETE_WITH("(");
+       else if (TailMatches("*)"))
+               COMPLETE_WITH("VISIBLE", "INVISIBLE");

/* CREATE OR REPLACE */
else if (Matches("CREATE", "OR"))

IMO, with the above in place, this patch is RFC.

Thank you Sami, really appreciate it!

Attached v16 with feedback and rebased.

Thanks
Shayon

Attachments:

v16-0001-Introduce-the-ability-to-set-index-visibility-us.patchapplication/x-patch; name=v16-0001-Introduce-the-ability-to-set-index-visibility-us.patchDownload
From b1833753476d2c7d062c6d3900b2671a09d32e12 Mon Sep 17 00:00:00 2001
From: Shayon Mukherjee <shayonj@gmail.com>
Date: Sun, 12 Jan 2025 14:34:48 -0500
Subject: [PATCH v16] Introduce the ability to set index visibility using ALTER
 INDEX

This patch introduces index visibility control using ALTER INDEX and CREATE INDEX
commands.

Original motivation for the problem and proposal for a patch
can be found at [1].

This patch passes all the existing specs and the newly added regression tests. The patch
is ready for review and test. It compiles, so the patch can be applied for testing as well.

Note: The patch has gone through a few iterations. Earlier versions of the patch had the ENABLE/DISABLE grammar.
The current version has the VISIBLE/INVISIBLE grammar. So, you will the local variable names using the new grammar accordingly.

Implementation details:

- New Grammar:
  * ALTER INDEX ... VISIBLE/INVISIBLE
  * CREATE INDEX ... INVISIBLE

- Default state is visible. Indexes are only invisible when explicitly
  instructed via CREATE INDEX ... INVISIBLE or ALTER INDEX ... INVISIBLE.

- Primary Key and Unique constraint indexes are always visible. The
  VISIBLE/INVISIBLE grammar is supported for these types of indexes and they can
  be made invisible via ALTER INDEX ... INVISIBLE.

- ALTER INDEX ... VISIBLE/INVISIBLE performs update on the relevant row in pg_index
  catalog

- pg_get_indexdef() supports the new functionality and grammar. This change is
  reflected in \d output for tables and pg_dump. We show the INVISIBLE syntax accordingly.

- Added force_invisible_index GUC parameter that forces the planner to use invisible
  indexes. This is useful for testing and validating index behavior without changing
  their visibility state. Based on feedback from Sami S [2]

- Updated create_index.sql regression test to cover the new grammar and verify
  that invisible indexes are not used in queries. The test covers:

  - Basic single-column and multi-column indexes
  - Partial indexes
  - Expression indexes
  - Join indexes
  - GIN and GiST indexes
  - Covering indexes
  - Range indexes
  - Unique indexes and constraints

- Adds a new indisvisible attribute to the IndexOptInfo structure.

- Modifies get_relation_info in plancat.c to skip invisible indexes entirely, thus reducing the number of places we need to check if an index is invisible or not. Inspired by the conversations start at [3].
  - I chose to modify the logic within get_relation_info as compared to, say, reducing the cost to make the planner not consider an index during planning, mostly to keep the number of changes being introduced to a minimum and also the logic itself being self-contained and easier to understand perhaps (?).

- No changes are made to stop the index from getting maintained. This way we ensure no
  data loss or corruption when index is made visible again.

- TOAST indexes are supported and visible by default as well.

- REINDEX CONCURRENTLY is supported as well and existing state of pg_index.indisvisible
  is carried over accordingly.

- See the changes in create_index.sql to get an idea of the grammar and sql statements.

- See the changes in create_index.out to get an idea of the catalogue states and EXPLAIN
  output to see when an index is getting used or isn't (when invisible).

- Incorporated DavidR's feedback from [4] around documentation and also you will see that by skipping invisible indexes entirely from get_relation_info in plancat.c (as mentioned above), we address the other mentioned issues as well.

- Lastly, protects against the case where indcheckxmin is true by raising ERRCODE_OBJECT_NOT_IN_PREREQUISITE_STATE.

Looking forward to any and all feedback on this patch, including but not limited to code quality, tests, fundamental logic.

[1] https://www.postgresql.org/message-id/CANqtF-oXKe0M%3D0QOih6H%2BsZRjE2BWAbkW_1%2B9nMEAMLxUJg5jA%40mail.gmail.com
[2] https://www.postgresql.org/message-id/CAA5RZ0udzydObMDi65C59-oq54B9ZmjSZ1wVH3h%2Bv4XiVm6QDA%40mail.gmail.com
[3] https://www.postgresql.org/message-id/3465209.1727202064%40sss.pgh.pa.us
[4] https://www.postgresql.org/message-id/CAApHDvpUNu%3DiVcdJ74sypvgeaCF%2Btfpyb8VRhZaF7DTd1xVr7g%40mail.gmail.com
---
 doc/src/sgml/catalogs.sgml                    |  11 +
 doc/src/sgml/config.sgml                      |  16 +
 doc/src/sgml/indices.sgml                     |  21 +
 doc/src/sgml/ref/alter_index.sgml             |  36 +
 doc/src/sgml/ref/create_index.sgml            |  29 +
 src/backend/bootstrap/bootparse.y             |   2 +
 src/backend/catalog/index.c                   |  31 +-
 src/backend/catalog/toasting.c                |   2 +-
 src/backend/commands/indexcmds.c              |   4 +
 src/backend/commands/tablecmds.c              |  92 +-
 src/backend/optimizer/util/plancat.c          |  30 +-
 src/backend/parser/gram.y                     |  56 +-
 src/backend/parser/parse_utilcmd.c            |   3 +
 src/backend/utils/adt/ruleutils.c             |   4 +
 src/backend/utils/cache/relcache.c            |   1 +
 src/backend/utils/misc/guc_tables.c           |  10 +
 src/backend/utils/misc/postgresql.conf.sample |   1 +
 src/bin/pg_dump/pg_dump.c                     |  21 +-
 src/bin/pg_dump/pg_dump.h                     |   2 +
 src/bin/pg_dump/t/002_pg_dump.pl              |  29 +
 src/bin/psql/describe.c                       |  15 +-
 src/bin/psql/tab-complete.in.c                |   5 +-
 src/include/catalog/index.h                   |   2 +-
 src/include/catalog/pg_index.h                |   2 +
 src/include/nodes/parsenodes.h                |   4 +
 src/include/optimizer/optimizer.h             |   5 +
 src/include/parser/kwlist.h                   |   2 +
 src/include/utils/guc_hooks.h                 |   1 +
 src/test/modules/test_ddl_deparse/Makefile    |   3 +-
 .../test_ddl_deparse/expected/alter_index.out |  29 +
 src/test/modules/test_ddl_deparse/meson.build |   1 +
 .../test_ddl_deparse/sql/alter_index.sql      |  18 +
 .../test_ddl_deparse/test_ddl_deparse.c       |   6 +
 src/test/regress/expected/create_index.out    | 795 ++++++++++++++++++
 src/test/regress/sql/create_index.sql         | 321 +++++++
 35 files changed, 1584 insertions(+), 26 deletions(-)
 create mode 100644 src/test/modules/test_ddl_deparse/expected/alter_index.out
 create mode 100644 src/test/modules/test_ddl_deparse/sql/alter_index.sql

diff --git a/doc/src/sgml/catalogs.sgml b/doc/src/sgml/catalogs.sgml
index cbd4e40a32..3307df883b 100644
--- a/doc/src/sgml/catalogs.sgml
+++ b/doc/src/sgml/catalogs.sgml
@@ -4618,6 +4618,17 @@ SCRAM-SHA-256$<replaceable>&lt;iteration count&gt;</replaceable>:<replaceable>&l
        partial index.
       </para></entry>
      </row>
+
+     <row>
+      <entry role="catalog_table_entry"><para role="column_definition">
+       <structfield>indisvisible</structfield> <type>bool</type>
+      </para>
+      <para>
+       If true, the index is currently visible to the planner and may be used for queries.
+       If false, the index is invisible and may not be used for queries,
+       but is still updated when the table is modified. Default is true.
+      </para></entry>
+     </row>
     </tbody>
    </tgroup>
   </table>
diff --git a/doc/src/sgml/config.sgml b/doc/src/sgml/config.sgml
index a8542fe41c..32087c07f9 100644
--- a/doc/src/sgml/config.sgml
+++ b/doc/src/sgml/config.sgml
@@ -5778,6 +5778,22 @@ ANY <replaceable class="parameter">num_sync</replaceable> ( <replaceable class="
       </listitem>
      </varlistentry>
 
+     <varlistentry id="guc-force-invisible-index" xreflabel="use_invisible_index">
+      <term><varname>use_invisible_index</varname> (<type>boolean</type>)
+      <indexterm>
+       <primary><varname>use_invisible_index</varname> configuration parameter</primary>
+      </indexterm>
+      </term>
+      <listitem>
+       <para>
+        Forces the query planner to consider indexes that have been marked as invisible using
+        <command>ALTER INDEX ... INVISIBLE</command>. This parameter is useful for selective
+        use of invisible indexes in specific application contexts. The default
+        is <literal>off</literal>.
+       </para>
+      </listitem>
+     </varlistentry>
+
      </variablelist>
      </sect2>
      <sect2 id="runtime-config-query-constants">
diff --git a/doc/src/sgml/indices.sgml b/doc/src/sgml/indices.sgml
index 9c4f76abf0..97bb599a05 100644
--- a/doc/src/sgml/indices.sgml
+++ b/doc/src/sgml/indices.sgml
@@ -1673,6 +1673,27 @@ CREATE INDEX test1c_content_y_index ON test1c (content COLLATE "y");
      <productname>PostgreSQL</productname> developers to examine the issue.
     </para>
    </listitem>
+
+   <listitem>
+    <para>
+     Invisible indexes provide a convenient way to experiment with indexes
+     without needing to fully drop and recreate them. You can create a new index as
+     invisible with <command>CREATE INDEX ... INVISIBLE</command> or mark
+     an existing index invisible with <command>ALTER INDEX ... INVISIBLE</command>.
+     When an index is invisible, the planner will ignore it by default.
+     To test the index's effect on performance, set the
+     <varname>use_invisible_index</varname> parameter to <literal>on</literal>.
+     This allows you to compare query performance with and without the index
+     before making it visible to all queries with
+     <command>ALTER INDEX ... VISIBLE</command>.
+    </para>
+    <para>
+     Similarly, before dropping an existing index that appears unused,
+     consider marking it invisible to verify that query performance doesn't
+     degrade. Check <structname>pg_stat_user_indexes</structname>.<structfield>idx_scan</structfield>
+     to identify potentially unused indexes.
+    </para>
+   </listitem>
   </itemizedlist>
  </sect1>
 </chapter>
diff --git a/doc/src/sgml/ref/alter_index.sgml b/doc/src/sgml/ref/alter_index.sgml
index 1d42d05d85..a49d28a52d 100644
--- a/doc/src/sgml/ref/alter_index.sgml
+++ b/doc/src/sgml/ref/alter_index.sgml
@@ -31,6 +31,7 @@ ALTER INDEX [ IF EXISTS ] <replaceable class="parameter">name</replaceable> ALTE
     SET STATISTICS <replaceable class="parameter">integer</replaceable>
 ALTER INDEX ALL IN TABLESPACE <replaceable class="parameter">name</replaceable> [ OWNED BY <replaceable class="parameter">role_name</replaceable> [, ... ] ]
     SET TABLESPACE <replaceable class="parameter">new_tablespace</replaceable> [ NOWAIT ]
+ALTER INDEX [ IF EXISTS ] <replaceable class="parameter">name</replaceable> { VISIBLE | INVISIBLE }
 </synopsis>
  </refsynopsisdiv>
 
@@ -159,6 +160,27 @@ ALTER INDEX ALL IN TABLESPACE <replaceable class="parameter">name</replaceable>
     </listitem>
    </varlistentry>
 
+   <varlistentry>
+    <term><literal>VISIBLE</literal></term>
+    <listitem>
+     <para>
+      Make the specified index visible. The index will be used for query planning.
+     </para>
+    </listitem>
+   </varlistentry>
+
+   <varlistentry>
+    <term><literal>INVISIBLE</literal></term>
+    <listitem>
+     <para>
+      Make the specified index invisible. The index will not be used for queries.
+      This can be useful for testing query performance with and without specific
+      indexes. If performance degrades after making an index invisible, it can be easily
+      be made visible using <literal>VISIBLE</literal>.
+     </para>
+    </listitem>
+   </varlistentry>
+
   </variablelist>
   </para>
 
@@ -301,6 +323,20 @@ CREATE INDEX coord_idx ON measured (x, y, (z + t));
 ALTER INDEX coord_idx ALTER COLUMN 3 SET STATISTICS 1000;
 </programlisting></para>
 
+  <para>
+   To make an index visible:
+<programlisting>
+ALTER INDEX idx_name VISIBLE;
+</programlisting>
+  </para>
+
+  <para>
+   To make an index invisible:
+<programlisting>
+ALTER INDEX idx_name INVISIBLE;
+</programlisting>
+  </para>
+
  </refsect1>
 
  <refsect1>
diff --git a/doc/src/sgml/ref/create_index.sgml b/doc/src/sgml/ref/create_index.sgml
index 208389e800..90d7d90a2b 100644
--- a/doc/src/sgml/ref/create_index.sgml
+++ b/doc/src/sgml/ref/create_index.sgml
@@ -28,6 +28,7 @@ CREATE [ UNIQUE ] INDEX [ CONCURRENTLY ] [ [ IF NOT EXISTS ] <replaceable class=
     [ WITH ( <replaceable class="parameter">storage_parameter</replaceable> [= <replaceable class="parameter">value</replaceable>] [, ... ] ) ]
     [ TABLESPACE <replaceable class="parameter">tablespace_name</replaceable> ]
     [ WHERE <replaceable class="parameter">predicate</replaceable> ]
+    [ INVISIBLE ]
 </synopsis>
  </refsynopsisdiv>
 
@@ -380,6 +381,19 @@ CREATE [ UNIQUE ] INDEX [ CONCURRENTLY ] [ [ IF NOT EXISTS ] <replaceable class=
       </listitem>
      </varlistentry>
 
+    <varlistentry>
+      <term><literal>INVISIBLE</literal></term>
+      <listitem>
+       <para>
+        Creates the index in an invisible state (default visible). An invisible index is
+        not used by the query planner for queries, but it is still maintained
+        when the underlying table data changes. This can be useful when you want to create
+        an index without immediately impacting query planning, allowing you to make it
+        visible later at a more convenient time. The index can be made visible later
+        using <command>ALTER INDEX ... VISIBLE</command>.
+       </para>
+      </listitem>
+     </varlistentry>
     </variablelist>
 
   <refsect2 id="sql-createindex-storage-parameters" xreflabel="Index Storage Parameters">
@@ -701,6 +715,14 @@ Indexes:
     partitioned index is a metadata only operation.
    </para>
 
+  <para>
+   When creating an index with the <literal>INVISIBLE</literal> option, the index
+   will be created but not used for query planning. This can be useful for
+   preparing an index in advance of its use, or for testing purposes. The index
+   will still be maintained as the table is modified, so it can be made visible
+   later without needing to be rebuilt. By default all new indexes are visible.
+  </para>
+
   </refsect2>
  </refsect1>
 
@@ -980,6 +1002,13 @@ SELECT * FROM points
 CREATE INDEX CONCURRENTLY sales_quantity_index ON sales_table (quantity);
 </programlisting></para>
 
+  <para>
+   To create an index on the table <literal>test_table</literal> with the default
+   name, but have it initially invisible:
+<programlisting>
+CREATE INDEX ON test_table (col1) INVISIBLE;
+</programlisting>
+  </para>
  </refsect1>
 
  <refsect1>
diff --git a/src/backend/bootstrap/bootparse.y b/src/backend/bootstrap/bootparse.y
index 9833f52c1b..ea21511a20 100644
--- a/src/backend/bootstrap/bootparse.y
+++ b/src/backend/bootstrap/bootparse.y
@@ -303,6 +303,7 @@ Boot_DeclareIndexStmt:
 					stmt->concurrent = false;
 					stmt->if_not_exists = false;
 					stmt->reset_default_tblspc = false;
+					stmt->isvisible = true;
 
 					/* locks and races need not concern us in bootstrap mode */
 					relationId = RangeVarGetRelid(stmt->relation, NoLock,
@@ -356,6 +357,7 @@ Boot_DeclareUniqueIndexStmt:
 					stmt->concurrent = false;
 					stmt->if_not_exists = false;
 					stmt->reset_default_tblspc = false;
+					stmt->isvisible = true;
 
 					/* locks and races need not concern us in bootstrap mode */
 					relationId = RangeVarGetRelid(stmt->relation, NoLock,
diff --git a/src/backend/catalog/index.c b/src/backend/catalog/index.c
index 739a92bdcc..2d8ceb60ce 100644
--- a/src/backend/catalog/index.c
+++ b/src/backend/catalog/index.c
@@ -119,7 +119,8 @@ static void UpdateIndexRelation(Oid indexoid, Oid heapoid,
 								bool isexclusion,
 								bool immediate,
 								bool isvalid,
-								bool isready);
+								bool isready,
+								bool isvisible);
 static void index_update_stats(Relation rel,
 							   bool hasindex,
 							   double reltuples);
@@ -571,7 +572,8 @@ UpdateIndexRelation(Oid indexoid,
 					bool isexclusion,
 					bool immediate,
 					bool isvalid,
-					bool isready)
+					bool isready,
+					bool isvisible)
 {
 	int2vector *indkey;
 	oidvector  *indcollation;
@@ -649,6 +651,7 @@ UpdateIndexRelation(Oid indexoid,
 	values[Anum_pg_index_indisready - 1] = BoolGetDatum(isready);
 	values[Anum_pg_index_indislive - 1] = BoolGetDatum(true);
 	values[Anum_pg_index_indisreplident - 1] = BoolGetDatum(false);
+	values[Anum_pg_index_indisvisible - 1] = BoolGetDatum(isvisible);
 	values[Anum_pg_index_indkey - 1] = PointerGetDatum(indkey);
 	values[Anum_pg_index_indcollation - 1] = PointerGetDatum(indcollation);
 	values[Anum_pg_index_indclass - 1] = PointerGetDatum(indclass);
@@ -714,6 +717,8 @@ UpdateIndexRelation(Oid indexoid,
  *			already exists.
  *		INDEX_CREATE_PARTITIONED:
  *			create a partitioned index (table must be partitioned)
+ *		INDEX_CREATE_VISIBLE:
+ *			create the index as visible to query planner
  * constr_flags: flags passed to index_constraint_create
  *		(only if INDEX_CREATE_ADD_CONSTRAINT is set)
  * allow_system_table_mods: allow table to be a system catalog
@@ -759,6 +764,7 @@ index_create(Relation heapRelation,
 	bool		invalid = (flags & INDEX_CREATE_INVALID) != 0;
 	bool		concurrent = (flags & INDEX_CREATE_CONCURRENT) != 0;
 	bool		partitioned = (flags & INDEX_CREATE_PARTITIONED) != 0;
+	bool		isvisible = (flags & INDEX_CREATE_VISIBLE) != 0;
 	char		relkind;
 	TransactionId relfrozenxid;
 	MultiXactId relminmxid;
@@ -1042,13 +1048,15 @@ index_create(Relation heapRelation,
 	 *	  (Or, could define a rule to maintain the predicate) --Nels, Feb '92
 	 * ----------------
 	 */
+
 	UpdateIndexRelation(indexRelationId, heapRelationId, parentIndexRelid,
 						indexInfo,
 						collationIds, opclassIds, coloptions,
 						isprimary, is_exclusion,
 						(constr_flags & INDEX_CONSTR_CREATE_DEFERRABLE) == 0,
 						!concurrent && !invalid,
-						!concurrent);
+						!concurrent,
+						isvisible);
 
 	/*
 	 * Register relcache invalidation on the indexes' heap relation, to
@@ -1317,6 +1325,8 @@ index_concurrently_create_copy(Relation heapRelation, Oid oldIndexId,
 	List	   *indexColNames = NIL;
 	List	   *indexExprs = NIL;
 	List	   *indexPreds = NIL;
+	Form_pg_index indexForm;
+	bits16		createFlags;
 
 	indexRelation = index_open(oldIndexId, RowExclusiveLock);
 
@@ -1344,6 +1354,9 @@ index_concurrently_create_copy(Relation heapRelation, Oid oldIndexId,
 											Anum_pg_index_indoption);
 	indcoloptions = (int2vector *) DatumGetPointer(colOptionDatum);
 
+	/* Get the visibility state of the original index */
+	indexForm = (Form_pg_index) GETSTRUCT(indexTuple);
+
 	/* Fetch reloptions of index if any */
 	classTuple = SearchSysCache1(RELOID, ObjectIdGetDatum(oldIndexId));
 	if (!HeapTupleIsValid(classTuple))
@@ -1435,6 +1448,16 @@ index_concurrently_create_copy(Relation heapRelation, Oid oldIndexId,
 		stattargets[i].isnull = isnull;
 	}
 
+	/*
+	 * Determine the create flags for the new index. We always use SKIP_BUILD
+	 * and CONCURRENT for concurrent reindexing. If the original index was
+	 * visible, we also set the VISIBLE flag to maintain the same state in the
+	 * new index.
+	 */
+	createFlags = INDEX_CREATE_SKIP_BUILD | INDEX_CREATE_CONCURRENT;
+	if (indexForm->indisvisible)
+		createFlags |= INDEX_CREATE_VISIBLE;
+
 	/*
 	 * Now create the new index.
 	 *
@@ -1458,7 +1481,7 @@ index_concurrently_create_copy(Relation heapRelation, Oid oldIndexId,
 							  indcoloptions->values,
 							  stattargets,
 							  reloptionsDatum,
-							  INDEX_CREATE_SKIP_BUILD | INDEX_CREATE_CONCURRENT,
+							  createFlags,
 							  0,
 							  true, /* allow table to be a system catalog? */
 							  false,	/* is_internal? */
diff --git a/src/backend/catalog/toasting.c b/src/backend/catalog/toasting.c
index 874a8fc89a..7721d16fd3 100644
--- a/src/backend/catalog/toasting.c
+++ b/src/backend/catalog/toasting.c
@@ -325,7 +325,7 @@ create_toast_table(Relation rel, Oid toastOid, Oid toastIndexOid,
 				 BTREE_AM_OID,
 				 rel->rd_rel->reltablespace,
 				 collationIds, opclassIds, NULL, coloptions, NULL, (Datum) 0,
-				 INDEX_CREATE_IS_PRIMARY, 0, true, true, NULL);
+				 INDEX_CREATE_IS_PRIMARY | INDEX_CREATE_VISIBLE, 0, true, true, NULL);
 
 	table_close(toast_rel, NoLock);
 
diff --git a/src/backend/commands/indexcmds.c b/src/backend/commands/indexcmds.c
index 33c2106c17..693f23e8d6 100644
--- a/src/backend/commands/indexcmds.c
+++ b/src/backend/commands/indexcmds.c
@@ -1222,6 +1222,10 @@ DefineIndex(Oid tableId,
 		flags |= INDEX_CREATE_PARTITIONED;
 	if (stmt->primary)
 		flags |= INDEX_CREATE_IS_PRIMARY;
+	if (stmt->isvisible)
+		flags |= INDEX_CREATE_VISIBLE;
+	else
+		flags &= ~INDEX_CREATE_VISIBLE;
 
 	/*
 	 * If the table is partitioned, and recursion was declined but partitions
diff --git a/src/backend/commands/tablecmds.c b/src/backend/commands/tablecmds.c
index 686f1850ca..a9d4fd7002 100644
--- a/src/backend/commands/tablecmds.c
+++ b/src/backend/commands/tablecmds.c
@@ -738,7 +738,8 @@ static List *GetParentedForeignKeyRefs(Relation partition);
 static void ATDetachCheckNoForeignKeyRefs(Relation partition);
 static char GetAttributeCompression(Oid atttypid, const char *compression);
 static char GetAttributeStorage(Oid atttypid, const char *storagemode);
-
+static void ATExecSetIndexVisibility(Relation rel, bool visible);
+static bool GetIndexVisibility(Oid indexOid);
 
 /* ----------------------------------------------------------------
  *		DefineRelation
@@ -4833,6 +4834,11 @@ AlterTableGetLockLevel(List *cmds)
 				cmd_lockmode = ShareUpdateExclusiveLock;
 				break;
 
+			case AT_SetIndexVisible:
+			case AT_SetIndexInvisible:
+				cmd_lockmode = ShareUpdateExclusiveLock;
+				break;
+
 			default:			/* oops */
 				elog(ERROR, "unrecognized alter table type: %d",
 					 (int) cmd->subtype);
@@ -5268,6 +5274,13 @@ ATPrepCmd(List **wqueue, Relation rel, AlterTableCmd *cmd,
 			/* No command-specific prep needed */
 			pass = AT_PASS_MISC;
 			break;
+		case AT_SetIndexVisible:
+		case AT_SetIndexInvisible:
+			ATSimplePermissions(cmd->subtype, rel, ATT_INDEX | ATT_PARTITIONED_INDEX);
+			ATSimpleRecursion(wqueue, rel, cmd, true, lockmode, context);
+			/* No command-specific prep needed */
+			pass = AT_PASS_MISC;
+			break;
 		default:				/* oops */
 			elog(ERROR, "unrecognized alter table type: %d",
 				 (int) cmd->subtype);
@@ -5664,6 +5677,12 @@ ATExecCmd(List **wqueue, AlteredTableInfo *tab,
 		case AT_DetachPartitionFinalize:
 			address = ATExecDetachPartitionFinalize(rel, ((PartitionCmd *) cmd->def)->name);
 			break;
+		case AT_SetIndexVisible:
+			ATExecSetIndexVisibility(rel, true);
+			break;
+		case AT_SetIndexInvisible:
+			ATExecSetIndexVisibility(rel, false);
+			break;
 		default:				/* oops */
 			elog(ERROR, "unrecognized alter table type: %d",
 				 (int) cmd->subtype);
@@ -6614,6 +6633,8 @@ alter_table_type_to_string(AlterTableType cmdtype)
 			return "DROP COLUMN";
 		case AT_AddIndex:
 		case AT_ReAddIndex:
+		case AT_SetIndexVisible:
+		case AT_SetIndexInvisible:
 			return NULL;		/* not real grammar */
 		case AT_AddConstraint:
 		case AT_ReAddConstraint:
@@ -15594,6 +15615,8 @@ ATPostAlterTypeParse(Oid oldId, Oid oldRelId, Oid refRelId, char *cmd,
 			stmt->reset_default_tblspc = true;
 			/* keep the index's comment */
 			stmt->idxcomment = GetComment(oldId, RelationRelationId, 0);
+			/* preserve the index's visibility status */
+			stmt->isvisible = GetIndexVisibility(oldId);
 
 			newcmd = makeNode(AlterTableCmd);
 			newcmd->subtype = AT_ReAddIndex;
@@ -15624,6 +15647,8 @@ ATPostAlterTypeParse(Oid oldId, Oid oldRelId, Oid refRelId, char *cmd,
 					indstmt->idxcomment = GetComment(indoid,
 													 RelationRelationId, 0);
 					indstmt->reset_default_tblspc = true;
+					/* preserve the index's visibility status */
+					indstmt->isvisible = GetIndexVisibility(indoid);
 
 					cmd->subtype = AT_ReAddIndex;
 					tab->subcmds[AT_PASS_OLD_INDEX] =
@@ -21981,3 +22006,68 @@ GetAttributeStorage(Oid atttypid, const char *storagemode)
 
 	return cstorage;
 }
+
+/*
+ * ATExecSetIndexVisibility
+ * Performs a catalog update to mark an index as visible or invisible in pg_index.
+ */
+static void
+ATExecSetIndexVisibility(Relation rel, bool visible)
+{
+	Oid			indexOid = RelationGetRelid(rel);
+	Oid			heapOid;
+	Relation	pg_index;
+	Relation	heapRel;
+	HeapTuple	indexTuple;
+	Form_pg_index indexForm;
+
+	heapOid = IndexGetRelation(indexOid, false);
+	heapRel = table_open(heapOid, AccessShareLock);
+	pg_index = table_open(IndexRelationId, RowExclusiveLock);
+
+	indexTuple = SearchSysCacheCopy1(INDEXRELID, ObjectIdGetDatum(indexOid));
+	if (!HeapTupleIsValid(indexTuple))
+		elog(ERROR, "cache lookup failed for index %u", indexOid);
+
+	indexForm = (Form_pg_index) GETSTRUCT(indexTuple);
+	if (indexForm->indcheckxmin)
+		ereport(ERROR,
+				errcode(ERRCODE_OBJECT_NOT_IN_PREREQUISITE_STATE),
+				errmsg("cannot update index visibility while indcheckxmin is true"),
+				errhint("Wait for all transactions that might see inconsistent HOT chains to complete"));
+
+	if (indexForm->indisvisible != visible)
+	{
+		indexForm->indisvisible = visible;
+		CatalogTupleUpdate(pg_index, &indexTuple->t_self, indexTuple);
+
+		CacheInvalidateRelcache(heapRel);
+		InvokeObjectPostAlterHook(IndexRelationId, indexOid, 0);
+		CommandCounterIncrement();
+	}
+
+	heap_freetuple(indexTuple);
+	table_close(pg_index, RowExclusiveLock);
+	table_close(heapRel, AccessShareLock);
+}
+
+/*
+* Get index visibility status from pg_index
+*/
+static bool
+GetIndexVisibility(Oid indexOid)
+{
+	HeapTuple	indexTuple;
+	Form_pg_index indexForm;
+	bool		isvisible;
+
+	indexTuple = SearchSysCache1(INDEXRELID, ObjectIdGetDatum(indexOid));
+	if (!HeapTupleIsValid(indexTuple))
+		elog(ERROR, "cache lookup failed for index %u", indexOid);
+
+	indexForm = (Form_pg_index) GETSTRUCT(indexTuple);
+	isvisible = indexForm->indisvisible;
+	ReleaseSysCache(indexTuple);
+
+	return isvisible;
+}
diff --git a/src/backend/optimizer/util/plancat.c b/src/backend/optimizer/util/plancat.c
index 59233b6473..6d938d3589 100644
--- a/src/backend/optimizer/util/plancat.c
+++ b/src/backend/optimizer/util/plancat.c
@@ -47,7 +47,9 @@
 #include "storage/bufmgr.h"
 #include "tcop/tcopprot.h"
 #include "utils/builtins.h"
+#include "utils/guc_hooks.h"
 #include "utils/lsyscache.h"
+#include "utils/plancache.h"
 #include "utils/partcache.h"
 #include "utils/rel.h"
 #include "utils/snapmgr.h"
@@ -55,6 +57,7 @@
 
 /* GUC parameter */
 int			constraint_exclusion = CONSTRAINT_EXCLUSION_PARTITION;
+bool		use_invisible_index = false;
 
 /* Hook for plugins to get control in get_relation_info() */
 get_relation_info_hook_type get_relation_info_hook = NULL;
@@ -256,13 +259,13 @@ get_relation_info(PlannerInfo *root, Oid relationObjectId, bool inhparent,
 			index = indexRelation->rd_index;
 
 			/*
-			 * Ignore invalid indexes, since they can't safely be used for
-			 * queries.  Note that this is OK because the data structure we
-			 * are constructing is only used by the planner --- the executor
-			 * still needs to insert into "invalid" indexes, if they're marked
-			 * indisready.
+			 * Skip invalid indexes, and invisible indexes unless
+			 * use_invisible_index is set. This is OK because the data
+			 * structure we are constructing is only used by the planner - the
+			 * executor still needs to insert into these indexes if they're
+			 * marked indisready.
 			 */
-			if (!index->indisvalid)
+			if (!index->indisvalid || (!index->indisvisible && !use_invisible_index))
 			{
 				index_close(indexRelation, NoLock);
 				continue;
@@ -2612,3 +2615,18 @@ set_baserel_partition_constraint(Relation relation, RelOptInfo *rel)
 		rel->partition_qual = partconstr;
 	}
 }
+
+/*
+ * assign_use_invisible_index
+ * GUC assign_hook for "use_invisible_index" GUC variable.
+ * Resets the plan cache when the value changes.
+ */
+void
+assign_use_invisible_index(bool newval, void *extra)
+{
+	if (use_invisible_index != newval)
+	{
+		use_invisible_index = newval;
+		ResetPlanCache();
+	}
+}
diff --git a/src/backend/parser/gram.y b/src/backend/parser/gram.y
index 3c4268b271..9a1b23c645 100644
--- a/src/backend/parser/gram.y
+++ b/src/backend/parser/gram.y
@@ -324,7 +324,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 %type <ival>	add_drop opt_asc_desc opt_nulls_order
 
 %type <node>	alter_table_cmd alter_type_cmd opt_collate_clause
-	   replica_identity partition_cmd index_partition_cmd
+	   replica_identity partition_cmd index_partition_cmd index_alter_cmd
 %type <list>	alter_table_cmds alter_type_cmds
 %type <list>    alter_identity_column_option_list
 %type <defelt>  alter_identity_column_option
@@ -491,6 +491,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 %type <boolean> opt_unique opt_verbose opt_full
 %type <boolean> opt_freeze opt_analyze opt_default
 %type <defelt>	opt_binary copy_delimiter
+%type <boolean>  opt_index_visibility
 
 %type <boolean> copy_from opt_program
 
@@ -733,7 +734,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 	IDENTITY_P IF_P ILIKE IMMEDIATE IMMUTABLE IMPLICIT_P IMPORT_P IN_P INCLUDE
 	INCLUDING INCREMENT INDENT INDEX INDEXES INHERIT INHERITS INITIALLY INLINE_P
 	INNER_P INOUT INPUT_P INSENSITIVE INSERT INSTEAD INT_P INTEGER
-	INTERSECT INTERVAL INTO INVOKER IS ISNULL ISOLATION
+	INTERSECT INTERVAL INTO INVISIBLE INVOKER IS ISNULL ISOLATION
 
 	JOIN JSON JSON_ARRAY JSON_ARRAYAGG JSON_EXISTS JSON_OBJECT JSON_OBJECTAGG
 	JSON_QUERY JSON_SCALAR JSON_SERIALIZE JSON_TABLE JSON_VALUE
@@ -784,7 +785,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 	UNLISTEN UNLOGGED UNTIL UPDATE USER USING
 
 	VACUUM VALID VALIDATE VALIDATOR VALUE_P VALUES VARCHAR VARIADIC VARYING
-	VERBOSE VERSION_P VIEW VIEWS VIRTUAL VOLATILE
+	VERBOSE VERSION_P VIEW VIEWS VIRTUAL VISIBLE VOLATILE
 
 	WHEN WHERE WHITESPACE_P WINDOW WITH WITHIN WITHOUT WORK WRAPPER WRITE
 
@@ -2157,6 +2158,24 @@ AlterTableStmt:
 					n->nowait = $13;
 					$$ = (Node *) n;
 				}
+		| ALTER INDEX qualified_name index_alter_cmd
+				{
+					AlterTableStmt *n = makeNode(AlterTableStmt);
+					n->relation = $3;
+					n->cmds = list_make1($4);
+					n->objtype = OBJECT_INDEX;
+					n->missing_ok = false;
+					$$ = (Node *) n;
+				}
+		| ALTER INDEX IF_P EXISTS qualified_name index_alter_cmd
+				{
+					AlterTableStmt *n = makeNode(AlterTableStmt);
+					n->relation = $5;
+					n->cmds = list_make1($6);
+					n->objtype = OBJECT_INDEX;
+					n->missing_ok = true;
+					$$ = (Node *) n;
+				}
 		|	ALTER INDEX qualified_name alter_table_cmds
 				{
 					AlterTableStmt *n = makeNode(AlterTableStmt);
@@ -2382,6 +2401,21 @@ index_partition_cmd:
 				}
 		;
 
+index_alter_cmd:
+		/* ALTER INDEX <name> VISIBLE|INVISIBLE */
+		VISIBLE
+			{
+				AlterTableCmd *n = makeNode(AlterTableCmd);
+				n->subtype = AT_SetIndexVisible;
+				$$ = (Node *) n;
+			}
+		| INVISIBLE
+			{
+				AlterTableCmd *n = makeNode(AlterTableCmd);
+				n->subtype = AT_SetIndexInvisible;
+				$$ = (Node *) n;
+			}
+		;
 alter_table_cmd:
 			/* ALTER TABLE <name> ADD <coldef> */
 			ADD_P columnDef
@@ -8190,7 +8224,7 @@ defacl_privilege_target:
 
 IndexStmt:	CREATE opt_unique INDEX opt_concurrently opt_single_name
 			ON relation_expr access_method_clause '(' index_params ')'
-			opt_include opt_unique_null_treatment opt_reloptions OptTableSpace where_clause
+			opt_include opt_unique_null_treatment opt_reloptions OptTableSpace where_clause opt_index_visibility
 				{
 					IndexStmt *n = makeNode(IndexStmt);
 
@@ -8205,6 +8239,7 @@ IndexStmt:	CREATE opt_unique INDEX opt_concurrently opt_single_name
 					n->options = $14;
 					n->tableSpace = $15;
 					n->whereClause = $16;
+					n->isvisible = $17;
 					n->excludeOpNames = NIL;
 					n->idxcomment = NULL;
 					n->indexOid = InvalidOid;
@@ -8222,7 +8257,7 @@ IndexStmt:	CREATE opt_unique INDEX opt_concurrently opt_single_name
 				}
 			| CREATE opt_unique INDEX opt_concurrently IF_P NOT EXISTS name
 			ON relation_expr access_method_clause '(' index_params ')'
-			opt_include opt_unique_null_treatment opt_reloptions OptTableSpace where_clause
+			opt_include opt_unique_null_treatment opt_reloptions OptTableSpace where_clause opt_index_visibility
 				{
 					IndexStmt *n = makeNode(IndexStmt);
 
@@ -8237,6 +8272,7 @@ IndexStmt:	CREATE opt_unique INDEX opt_concurrently opt_single_name
 					n->options = $17;
 					n->tableSpace = $18;
 					n->whereClause = $19;
+					n->isvisible = $20;
 					n->excludeOpNames = NIL;
 					n->idxcomment = NULL;
 					n->indexOid = InvalidOid;
@@ -8259,6 +8295,12 @@ opt_unique:
 			| /*EMPTY*/								{ $$ = false; }
 		;
 
+opt_index_visibility:
+			VISIBLE                       { $$ = true; }
+			| INVISIBLE                   { $$ = false; }
+			| /*EMPTY*/                   { $$ = true; }
+		;
+
 access_method_clause:
 			USING name								{ $$ = $2; }
 			| /*EMPTY*/								{ $$ = DEFAULT_INDEX_TYPE; }
@@ -17836,6 +17878,7 @@ unreserved_keyword:
 			| INSENSITIVE
 			| INSERT
 			| INSTEAD
+			| INVISIBLE
 			| INVOKER
 			| ISOLATION
 			| KEEP
@@ -18022,6 +18065,7 @@ unreserved_keyword:
 			| VIEW
 			| VIEWS
 			| VIRTUAL
+			| VISIBLE
 			| VOLATILE
 			| WHITESPACE_P
 			| WITHIN
@@ -18431,6 +18475,7 @@ bare_label_keyword:
 			| INT_P
 			| INTEGER
 			| INTERVAL
+			| INVISIBLE
 			| INVOKER
 			| IS
 			| ISOLATION
@@ -18679,6 +18724,7 @@ bare_label_keyword:
 			| VIEW
 			| VIEWS
 			| VIRTUAL
+			| VISIBLE
 			| VOLATILE
 			| WHEN
 			| WHITESPACE_P
diff --git a/src/backend/parser/parse_utilcmd.c b/src/backend/parser/parse_utilcmd.c
index 62015431fd..0619833c09 100644
--- a/src/backend/parser/parse_utilcmd.c
+++ b/src/backend/parser/parse_utilcmd.c
@@ -1745,6 +1745,7 @@ generateClonedIndexStmt(RangeVar *heapRel, Relation source_idx,
 	index->concurrent = false;
 	index->if_not_exists = false;
 	index->reset_default_tblspc = false;
+	index->isvisible = idxrec->indisvisible;
 
 	/*
 	 * We don't try to preserve the name of the source index; instead, just
@@ -2366,6 +2367,8 @@ transformIndexConstraint(Constraint *constraint, CreateStmtContext *cxt)
 	index->concurrent = false;
 	index->if_not_exists = false;
 	index->reset_default_tblspc = constraint->reset_default_tblspc;
+	/* Ensure indexes for constraints are created as visible by default */
+	index->isvisible = true;
 
 	/*
 	 * If it's ALTER TABLE ADD CONSTRAINT USING INDEX, look up the index and
diff --git a/src/backend/utils/adt/ruleutils.c b/src/backend/utils/adt/ruleutils.c
index 9e90acedb9..199781c1ab 100644
--- a/src/backend/utils/adt/ruleutils.c
+++ b/src/backend/utils/adt/ruleutils.c
@@ -1565,6 +1565,10 @@ pg_get_indexdef_worker(Oid indexrelid, int colno,
 			else
 				appendStringInfo(&buf, " WHERE %s", str);
 		}
+
+		/* Add INVISIBLE clause if the index is invisible */
+		if (!idxrec->indisvisible)
+			appendStringInfoString(&buf, " INVISIBLE");
 	}
 
 	/* Clean up */
diff --git a/src/backend/utils/cache/relcache.c b/src/backend/utils/cache/relcache.c
index 2905ae86a2..b1d9dd769c 100644
--- a/src/backend/utils/cache/relcache.c
+++ b/src/backend/utils/cache/relcache.c
@@ -2344,6 +2344,7 @@ RelationReloadIndexInfo(Relation relation)
 		relation->rd_index->indisready = index->indisready;
 		relation->rd_index->indislive = index->indislive;
 		relation->rd_index->indisreplident = index->indisreplident;
+		relation->rd_index->indisvisible = index->indisvisible;
 
 		/* Copy xmin too, as that is needed to make sense of indcheckxmin */
 		HeapTupleHeaderSetXmin(relation->rd_indextuple->t_data,
diff --git a/src/backend/utils/misc/guc_tables.c b/src/backend/utils/misc/guc_tables.c
index f596fda568..902af28105 100644
--- a/src/backend/utils/misc/guc_tables.c
+++ b/src/backend/utils/misc/guc_tables.c
@@ -2130,6 +2130,16 @@ struct config_bool ConfigureNamesBool[] =
 		true,
 		NULL, NULL, NULL
 	},
+	{
+		{"use_invisible_index", PGC_USERSET, QUERY_TUNING_OTHER,
+			gettext_noop("Forces the planner to consider invisible indexes."),
+			NULL,
+			GUC_EXPLAIN
+		},
+		&use_invisible_index,
+		false,
+		NULL, assign_use_invisible_index, NULL
+	},
 
 	/* End-of-list marker */
 	{
diff --git a/src/backend/utils/misc/postgresql.conf.sample b/src/backend/utils/misc/postgresql.conf.sample
index 25fe90a430..b1c15a7fd8 100644
--- a/src/backend/utils/misc/postgresql.conf.sample
+++ b/src/backend/utils/misc/postgresql.conf.sample
@@ -428,6 +428,7 @@
 #enable_group_by_reordering = on
 #enable_distinct_reordering = on
 #enable_self_join_elimination = on
+#use_invisible_index = off		# forces planner to consider invisible indexes
 
 # - Planner Cost Constants -
 
diff --git a/src/bin/pg_dump/pg_dump.c b/src/bin/pg_dump/pg_dump.c
index 25264f8c9f..aed8461f7a 100644
--- a/src/bin/pg_dump/pg_dump.c
+++ b/src/bin/pg_dump/pg_dump.c
@@ -7647,7 +7647,8 @@ getIndexes(Archive *fout, TableInfo tblinfo[], int numTables)
 				i_tablespace,
 				i_indreloptions,
 				i_indstatcols,
-				i_indstatvals;
+				i_indstatvals,
+				i_indisvisible;
 
 	/*
 	 * We want to perform just one query against pg_index.  However, we
@@ -7690,7 +7691,7 @@ getIndexes(Archive *fout, TableInfo tblinfo[], int numTables)
 
 	appendPQExpBufferStr(query,
 						 "pg_catalog.pg_get_indexdef(i.indexrelid) AS indexdef, "
-						 "i.indkey, i.indisclustered, "
+						 "i.indkey, i.indisclustered, i.indisvisible, "
 						 "c.contype, c.conname, "
 						 "c.condeferrable, c.condeferred, "
 						 "c.tableoid AS contableoid, "
@@ -7712,6 +7713,13 @@ getIndexes(Archive *fout, TableInfo tblinfo[], int numTables)
 		appendPQExpBufferStr(query,
 							 "false AS indisreplident, ");
 
+	if (fout->remoteVersion >= 180000)
+		appendPQExpBufferStr(query,
+							 "i.indisvisible, ");
+	else
+		appendPQExpBufferStr(query,
+							 "true AS indisvisible, ");
+
 	if (fout->remoteVersion >= 110000)
 		appendPQExpBufferStr(query,
 							 "inh.inhparent AS parentidx, "
@@ -7826,6 +7834,7 @@ getIndexes(Archive *fout, TableInfo tblinfo[], int numTables)
 	i_indreloptions = PQfnumber(res, "indreloptions");
 	i_indstatcols = PQfnumber(res, "indstatcols");
 	i_indstatvals = PQfnumber(res, "indstatvals");
+	i_indisvisible = PQfnumber(res, "indisvisible");
 
 	indxinfo = (IndxInfo *) pg_malloc(ntups * sizeof(IndxInfo));
 
@@ -7916,7 +7925,7 @@ getIndexes(Archive *fout, TableInfo tblinfo[], int numTables)
 								  &indAttNames, &nindAttNames))
 					pg_fatal("could not parse %s array", "indattnames");
 			}
-
+			indxinfo[j].indisvisible = (PQgetvalue(res, j, i_indisvisible)[0] == 't');
 			relstats = getRelationStatistics(fout, &indxinfo[j].dobj, relpages,
 											 PQgetvalue(res, j, i_reltuples),
 											 relallvisible, relallfrozen, indexkind,
@@ -18217,6 +18226,12 @@ dumpConstraint(Archive *fout, const ConstraintInfo *coninfo)
 			}
 
 			appendPQExpBufferStr(q, ";\n");
+
+			if (!indxinfo->indisvisible)
+			{
+				appendPQExpBuffer(q, "ALTER INDEX %s INVISIBLE;\n",
+								  fmtQualifiedDumpable(indxinfo));
+			}
 		}
 
 		/*
diff --git a/src/bin/pg_dump/pg_dump.h b/src/bin/pg_dump/pg_dump.h
index b426b5e473..55d0203df3 100644
--- a/src/bin/pg_dump/pg_dump.h
+++ b/src/bin/pg_dump/pg_dump.h
@@ -427,6 +427,8 @@ typedef struct _indxInfo
 
 	/* if there is an associated constraint object, its dumpId: */
 	DumpId		indexconstraint;
+
+	bool		indisvisible;
 } IndxInfo;
 
 typedef struct _indexAttachInfo
diff --git a/src/bin/pg_dump/t/002_pg_dump.pl b/src/bin/pg_dump/t/002_pg_dump.pl
index 6c03eca8e5..4bc579eb49 100644
--- a/src/bin/pg_dump/t/002_pg_dump.pl
+++ b/src/bin/pg_dump/t/002_pg_dump.pl
@@ -2185,6 +2185,35 @@ my %tests = (
 		like => {},
 	},
 
+	'ALTER TABLE ONLY test_table ADD CONSTRAINT ... PRIMARY KEY INVISIBLE' => {
+		create_order => 97,
+		create_sql => 'CREATE TABLE dump_test.test_table_invisible (
+					   id int PRIMARY KEY
+					  );
+					  ALTER INDEX dump_test.test_table_invisible_pkey INVISIBLE;',
+		regexp => qr/^
+			\QALTER TABLE ONLY dump_test.test_table_invisible\E\n\s+
+			\QADD CONSTRAINT test_table_invisible_pkey PRIMARY KEY (id);\E\n
+			\QALTER INDEX dump_test.test_table_invisible_pkey INVISIBLE;\E
+			/xm,
+		like => { %full_runs, %dump_test_schema_runs, section_post_data => 1 },
+		unlike => { exclude_dump_test_schema => 1, only_dump_measurement => 1 },
+	},
+
+	'CREATE INDEX ... INVISIBLE' => {
+		create_order => 98,
+		create_sql => 'CREATE TABLE dump_test.test_table_mixed_indexes (
+					   id int,
+					   value int
+					  );
+					  CREATE INDEX idx_visible ON dump_test.test_table_mixed_indexes(value);
+					  CREATE UNIQUE INDEX idx_invisible ON dump_test.test_table_mixed_indexes(value) INVISIBLE;
+					  ALTER INDEX dump_test.idx_invisible INVISIBLE;',
+		regexp => qr/CREATE UNIQUE INDEX idx_invisible ON dump_test\.test_table_mixed_indexes USING btree \(value\) INVISIBLE;/m,
+		like => { %full_runs, %dump_test_schema_runs, section_post_data => 1 },
+		unlike => { exclude_dump_test_schema => 1, only_dump_measurement => 1 },
+	},
+
 	'CREATE AGGREGATE dump_test.newavg' => {
 		create_order => 25,
 		create_sql => 'CREATE AGGREGATE dump_test.newavg (
diff --git a/src/bin/psql/describe.c b/src/bin/psql/describe.c
index 1d08268393..bdb7397814 100644
--- a/src/bin/psql/describe.c
+++ b/src/bin/psql/describe.c
@@ -2329,6 +2329,11 @@ describeOneTableDetails(const char *schemaname,
 		else
 			appendPQExpBufferStr(&buf, "false AS indnullsnotdistinct,\n");
 
+		if (pset.sversion >= 180000)
+			appendPQExpBufferStr(&buf, "i.indisvisible,\n");
+		else
+			appendPQExpBufferStr(&buf, "true AS indisvisible,\n");
+
 		appendPQExpBuffer(&buf, "  a.amname, c2.relname, "
 						  "pg_catalog.pg_get_expr(i.indpred, i.indrelid, true)\n"
 						  "FROM pg_catalog.pg_index i, pg_catalog.pg_class c, pg_catalog.pg_class c2, pg_catalog.pg_am a\n"
@@ -2354,9 +2359,10 @@ describeOneTableDetails(const char *schemaname,
 			char	   *deferred = PQgetvalue(result, 0, 5);
 			char	   *indisreplident = PQgetvalue(result, 0, 6);
 			char	   *indnullsnotdistinct = PQgetvalue(result, 0, 7);
-			char	   *indamname = PQgetvalue(result, 0, 8);
-			char	   *indtable = PQgetvalue(result, 0, 9);
-			char	   *indpred = PQgetvalue(result, 0, 10);
+			char	   *indisvisible = PQgetvalue(result, 0, 8);
+			char	   *indamname = PQgetvalue(result, 0, 9);
+			char	   *indtable = PQgetvalue(result, 0, 10);
+			char	   *indpred = PQgetvalue(result, 0, 11);
 
 			if (strcmp(indisprimary, "t") == 0)
 				printfPQExpBuffer(&tmpbuf, _("primary key, "));
@@ -2393,6 +2399,9 @@ describeOneTableDetails(const char *schemaname,
 			if (strcmp(indisreplident, "t") == 0)
 				appendPQExpBufferStr(&tmpbuf, _(", replica identity"));
 
+			if (strcmp(indisvisible, "t") != 0)
+				appendPQExpBufferStr(&tmpbuf, _(", invisible"));
+
 			printTableAddFooter(&cont, tmpbuf.data);
 
 			/*
diff --git a/src/bin/psql/tab-complete.in.c b/src/bin/psql/tab-complete.in.c
index c916b9299a..f1853a68cc 100644
--- a/src/bin/psql/tab-complete.in.c
+++ b/src/bin/psql/tab-complete.in.c
@@ -2419,7 +2419,8 @@ match_previous_words(int pattern_id,
 	else if (Matches("ALTER", "INDEX", MatchAny))
 		COMPLETE_WITH("ALTER COLUMN", "OWNER TO", "RENAME TO", "SET",
 					  "RESET", "ATTACH PARTITION",
-					  "DEPENDS ON EXTENSION", "NO DEPENDS ON EXTENSION");
+					  "DEPENDS ON EXTENSION", "NO DEPENDS ON EXTENSION",
+					  "INVISIBLE", "VISIBLE");
 	else if (Matches("ALTER", "INDEX", MatchAny, "ATTACH"))
 		COMPLETE_WITH("PARTITION");
 	else if (Matches("ALTER", "INDEX", MatchAny, "ATTACH", "PARTITION"))
@@ -3433,6 +3434,8 @@ match_previous_words(int pattern_id,
 			 !TailMatches("POLICY", MatchAny, MatchAny, MatchAny, MatchAny, MatchAny) &&
 			 !TailMatches("FOR", MatchAny, MatchAny, MatchAny))
 		COMPLETE_WITH("(");
+	else if (TailMatches("*)"))
+		COMPLETE_WITH("VISIBLE", "INVISIBLE");
 
 	/* CREATE OR REPLACE */
 	else if (Matches("CREATE", "OR"))
diff --git a/src/include/catalog/index.h b/src/include/catalog/index.h
index 4daa8bef5e..75bef5bd88 100644
--- a/src/include/catalog/index.h
+++ b/src/include/catalog/index.h
@@ -65,6 +65,7 @@ extern void index_check_primary_key(Relation heapRel,
 #define	INDEX_CREATE_IF_NOT_EXISTS			(1 << 4)
 #define	INDEX_CREATE_PARTITIONED			(1 << 5)
 #define INDEX_CREATE_INVALID				(1 << 6)
+#define INDEX_CREATE_VISIBLE				(1 << 7)
 
 extern Oid	index_create(Relation heapRelation,
 						 const char *indexRelationName,
@@ -175,7 +176,6 @@ extern void RestoreReindexState(const void *reindexstate);
 
 extern void IndexSetParentIndex(Relation partitionIdx, Oid parentOid);
 
-
 /*
  * itemptr_encode - Encode ItemPointer as int64/int8
  *
diff --git a/src/include/catalog/pg_index.h b/src/include/catalog/pg_index.h
index 4392b9d221..ec8e5dc4bf 100644
--- a/src/include/catalog/pg_index.h
+++ b/src/include/catalog/pg_index.h
@@ -44,6 +44,8 @@ CATALOG(pg_index,2610,IndexRelationId) BKI_SCHEMA_MACRO
 	bool		indisready;		/* is this index ready for inserts? */
 	bool		indislive;		/* is this index alive at all? */
 	bool		indisreplident; /* is this index the identity for replication? */
+	bool		indisvisible BKI_DEFAULT(t);	/* is this index visible for
+												 * use by queries? */
 
 	/* variable-length fields start here, but we allow direct access to indkey */
 	int2vector	indkey BKI_FORCE_NOT_NULL;	/* column numbers of indexed cols,
diff --git a/src/include/nodes/parsenodes.h b/src/include/nodes/parsenodes.h
index 4610fc6129..92a14b82f5 100644
--- a/src/include/nodes/parsenodes.h
+++ b/src/include/nodes/parsenodes.h
@@ -2472,6 +2472,8 @@ typedef enum AlterTableType
 	AT_SetIdentity,				/* SET identity column options */
 	AT_DropIdentity,			/* DROP IDENTITY */
 	AT_ReAddStatistics,			/* internal to commands/tablecmds.c */
+	AT_SetIndexVisible,			/* Set INDEX visible */
+	AT_SetIndexInvisible,		/* Set INDEX invisible */
 } AlterTableType;
 
 typedef struct AlterTableCmd	/* one subcommand of an ALTER TABLE */
@@ -3470,6 +3472,8 @@ typedef struct IndexStmt
 	bool		if_not_exists;	/* just do nothing if index already exists? */
 	bool		reset_default_tblspc;	/* reset default_tablespace prior to
 										 * executing */
+	bool		isvisible;		/* true if VISIBLE (default), false if
+								 * INVISIBLE */
 } IndexStmt;
 
 /* ----------------------
diff --git a/src/include/optimizer/optimizer.h b/src/include/optimizer/optimizer.h
index 546828b54b..3b5ca55bae 100644
--- a/src/include/optimizer/optimizer.h
+++ b/src/include/optimizer/optimizer.h
@@ -212,4 +212,9 @@ extern List *pull_var_clause(Node *node, int flags);
 extern Node *flatten_join_alias_vars(PlannerInfo *root, Query *query, Node *node);
 extern Node *flatten_group_exprs(PlannerInfo *root, Query *query, Node *node);
 
+/*
+ * GUC to tell planner to consider invisible indexes.
+ */
+extern bool use_invisible_index;
+
 #endif							/* OPTIMIZER_H */
diff --git a/src/include/parser/kwlist.h b/src/include/parser/kwlist.h
index a4af3f717a..77da5117cb 100644
--- a/src/include/parser/kwlist.h
+++ b/src/include/parser/kwlist.h
@@ -229,6 +229,7 @@ PG_KEYWORD("integer", INTEGER, COL_NAME_KEYWORD, BARE_LABEL)
 PG_KEYWORD("intersect", INTERSECT, RESERVED_KEYWORD, AS_LABEL)
 PG_KEYWORD("interval", INTERVAL, COL_NAME_KEYWORD, BARE_LABEL)
 PG_KEYWORD("into", INTO, RESERVED_KEYWORD, AS_LABEL)
+PG_KEYWORD("invisible", INVISIBLE, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("invoker", INVOKER, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("is", IS, TYPE_FUNC_NAME_KEYWORD, BARE_LABEL)
 PG_KEYWORD("isnull", ISNULL, TYPE_FUNC_NAME_KEYWORD, AS_LABEL)
@@ -493,6 +494,7 @@ PG_KEYWORD("version", VERSION_P, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("view", VIEW, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("views", VIEWS, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("virtual", VIRTUAL, UNRESERVED_KEYWORD, BARE_LABEL)
+PG_KEYWORD("visible", VISIBLE, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("volatile", VOLATILE, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("when", WHEN, RESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("where", WHERE, RESERVED_KEYWORD, AS_LABEL)
diff --git a/src/include/utils/guc_hooks.h b/src/include/utils/guc_hooks.h
index 799fa7ace6..dd5128fd87 100644
--- a/src/include/utils/guc_hooks.h
+++ b/src/include/utils/guc_hooks.h
@@ -178,5 +178,6 @@ extern bool check_synchronized_standby_slots(char **newval, void **extra,
 extern void assign_synchronized_standby_slots(const char *newval, void *extra);
 extern bool check_idle_replication_slot_timeout(int *newval, void **extra,
 												GucSource source);
+extern void assign_use_invisible_index(bool newval, void *extra);
 
 #endif							/* GUC_HOOKS_H */
diff --git a/src/test/modules/test_ddl_deparse/Makefile b/src/test/modules/test_ddl_deparse/Makefile
index 3a57a95c84..747d8b5835 100644
--- a/src/test/modules/test_ddl_deparse/Makefile
+++ b/src/test/modules/test_ddl_deparse/Makefile
@@ -27,7 +27,8 @@ REGRESS = test_ddl_deparse \
 	alter_type_enum \
 	opfamily \
 	defprivs \
-	matviews
+	matviews \
+	alter_index
 
 EXTRA_INSTALL = contrib/pg_stat_statements
 
diff --git a/src/test/modules/test_ddl_deparse/expected/alter_index.out b/src/test/modules/test_ddl_deparse/expected/alter_index.out
new file mode 100644
index 0000000000..f502baf1c5
--- /dev/null
+++ b/src/test/modules/test_ddl_deparse/expected/alter_index.out
@@ -0,0 +1,29 @@
+-- Test index visibility commands
+CREATE TABLE visibility_test (id int);
+NOTICE:  DDL test: type simple, tag CREATE TABLE
+CREATE INDEX idx_vis ON visibility_test(id);
+NOTICE:  DDL test: type simple, tag CREATE INDEX
+ALTER INDEX idx_vis INVISIBLE;
+NOTICE:  DDL test: type alter table, tag ALTER INDEX
+NOTICE:    subcommand: type SET INVISIBLE desc <NULL>
+ALTER INDEX idx_vis VISIBLE;
+NOTICE:  DDL test: type alter table, tag ALTER INDEX
+NOTICE:    subcommand: type SET VISIBLE desc <NULL>
+ALTER INDEX idx_vis INVISIBLE;
+NOTICE:  DDL test: type alter table, tag ALTER INDEX
+NOTICE:    subcommand: type SET INVISIBLE desc <NULL>
+REINDEX INDEX idx_vis;
+NOTICE:  DDL test: type simple, tag REINDEX
+CREATE SCHEMA visibility_schema;
+NOTICE:  DDL test: type simple, tag CREATE SCHEMA
+CREATE TABLE visibility_schema.test2 (id int);
+NOTICE:  DDL test: type simple, tag CREATE TABLE
+CREATE INDEX idx_vis2 ON visibility_schema.test2(id);
+NOTICE:  DDL test: type simple, tag CREATE INDEX
+ALTER INDEX visibility_schema.idx_vis2 INVISIBLE;
+NOTICE:  DDL test: type alter table, tag ALTER INDEX
+NOTICE:    subcommand: type SET INVISIBLE desc <NULL>
+-- Clean up
+DROP SCHEMA visibility_schema CASCADE;
+NOTICE:  drop cascades to table visibility_schema.test2
+DROP TABLE visibility_test CASCADE;
diff --git a/src/test/modules/test_ddl_deparse/meson.build b/src/test/modules/test_ddl_deparse/meson.build
index bff65ba633..6654b5e46d 100644
--- a/src/test/modules/test_ddl_deparse/meson.build
+++ b/src/test/modules/test_ddl_deparse/meson.build
@@ -48,6 +48,7 @@ tests += {
       'opfamily',
       'defprivs',
       'matviews',
+      'alter_index',
     ],
   },
 }
diff --git a/src/test/modules/test_ddl_deparse/sql/alter_index.sql b/src/test/modules/test_ddl_deparse/sql/alter_index.sql
new file mode 100644
index 0000000000..7a34dc6692
--- /dev/null
+++ b/src/test/modules/test_ddl_deparse/sql/alter_index.sql
@@ -0,0 +1,18 @@
+-- Test index visibility commands
+CREATE TABLE visibility_test (id int);
+CREATE INDEX idx_vis ON visibility_test(id);
+
+ALTER INDEX idx_vis INVISIBLE;
+ALTER INDEX idx_vis VISIBLE;
+
+ALTER INDEX idx_vis INVISIBLE;
+REINDEX INDEX idx_vis;
+
+CREATE SCHEMA visibility_schema;
+CREATE TABLE visibility_schema.test2 (id int);
+CREATE INDEX idx_vis2 ON visibility_schema.test2(id);
+ALTER INDEX visibility_schema.idx_vis2 INVISIBLE;
+
+-- Clean up
+DROP SCHEMA visibility_schema CASCADE;
+DROP TABLE visibility_test CASCADE;
diff --git a/src/test/modules/test_ddl_deparse/test_ddl_deparse.c b/src/test/modules/test_ddl_deparse/test_ddl_deparse.c
index 193669f2bc..8d7c7e5894 100644
--- a/src/test/modules/test_ddl_deparse/test_ddl_deparse.c
+++ b/src/test/modules/test_ddl_deparse/test_ddl_deparse.c
@@ -308,6 +308,12 @@ get_altertable_subcmdinfo(PG_FUNCTION_ARGS)
 			case AT_ReAddStatistics:
 				strtype = "(re) ADD STATS";
 				break;
+			case AT_SetIndexVisible:
+				strtype = "SET VISIBLE";
+				break;
+			case AT_SetIndexInvisible:
+				strtype = "SET INVISIBLE";
+				break;
 		}
 
 		if (subcmd->recurse)
diff --git a/src/test/regress/expected/create_index.out b/src/test/regress/expected/create_index.out
index 9ade7b835e..2ba2397a12 100644
--- a/src/test/regress/expected/create_index.out
+++ b/src/test/regress/expected/create_index.out
@@ -3542,6 +3542,801 @@ ERROR:  REINDEX SCHEMA cannot run inside a transaction block
 END;
 -- concurrently
 REINDEX SCHEMA CONCURRENTLY schema_to_reindex;
+-- Test index visibility functionality
+CREATE TABLE index_test(
+    id INT PRIMARY KEY,
+    data TEXT,
+    num INT,
+    vector INT[],
+    range INT4RANGE
+);
+INSERT INTO index_test
+SELECT
+    g,
+    'data ' || g,
+    g % 100,
+    ARRAY[g, g+1, g+2],
+    int4range(g, g+10)
+FROM generate_series(1, 1000) g;
+-- Function for testing
+CREATE FUNCTION get_data_length(text) RETURNS INT AS $$
+    SELECT length($1);
+$$ LANGUAGE SQL IMMUTABLE;
+-- Helper function to show index status
+CREATE OR REPLACE FUNCTION show_index_status(index_name text)
+RETURNS TABLE (
+    indexrelid regclass,
+    indisvalid boolean,
+    indisready boolean,
+    indislive boolean,
+    indisvisible boolean
+) AS $$
+BEGIN
+    RETURN QUERY EXECUTE format('
+        SELECT indexrelid::regclass, indisvalid, indisready, indislive, indisvisible
+        FROM pg_index
+        WHERE indexrelid = %L::regclass', index_name);
+END;
+$$ LANGUAGE plpgsql;
+-- Create and test each index type
+-- 1. Basic single-column index
+CREATE INDEX idx_single ON index_test(data);
+SELECT show_index_status('idx_single');
+  show_index_status   
+----------------------
+ (idx_single,t,t,t,t)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE data = 'data 500';
+                  QUERY PLAN                   
+-----------------------------------------------
+ Bitmap Heap Scan on index_test
+   Recheck Cond: (data = 'data 500'::text)
+   ->  Bitmap Index Scan on idx_single
+         Index Cond: (data = 'data 500'::text)
+(4 rows)
+
+ALTER INDEX idx_single INVISIBLE;
+SELECT show_index_status('idx_single');
+  show_index_status   
+----------------------
+ (idx_single,t,t,t,f)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE data = 'data 500';
+             QUERY PLAN              
+-------------------------------------
+ Seq Scan on index_test
+   Filter: (data = 'data 500'::text)
+(2 rows)
+
+ALTER INDEX idx_single VISIBLE;
+SELECT show_index_status('idx_single');
+  show_index_status   
+----------------------
+ (idx_single,t,t,t,t)
+(1 row)
+
+-- 2. Multi-column index
+CREATE INDEX idx_multi ON index_test(num, data);
+SELECT show_index_status('idx_multi');
+  show_index_status  
+---------------------
+ (idx_multi,t,t,t,t)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE num = 50 AND data > 'data 500';
+                           QUERY PLAN                           
+----------------------------------------------------------------
+ Bitmap Heap Scan on index_test
+   Recheck Cond: ((num = 50) AND (data > 'data 500'::text))
+   ->  Bitmap Index Scan on idx_multi
+         Index Cond: ((num = 50) AND (data > 'data 500'::text))
+(4 rows)
+
+ALTER INDEX idx_multi INVISIBLE;
+SELECT show_index_status('idx_multi');
+  show_index_status  
+---------------------
+ (idx_multi,t,t,t,f)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE num = 50 AND data > 'data 500';
+                      QUERY PLAN                      
+------------------------------------------------------
+ Seq Scan on index_test
+   Filter: ((data > 'data 500'::text) AND (num = 50))
+(2 rows)
+
+ALTER INDEX idx_multi VISIBLE;
+SELECT show_index_status('idx_multi');
+  show_index_status  
+---------------------
+ (idx_multi,t,t,t,t)
+(1 row)
+
+-- 3. Partial index
+CREATE INDEX idx_partial ON index_test(num) WHERE num < 50;
+SELECT show_index_status('idx_partial');
+   show_index_status   
+-----------------------
+ (idx_partial,t,t,t,t)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE num = 25;
+               QUERY PLAN               
+----------------------------------------
+ Bitmap Heap Scan on index_test
+   Recheck Cond: (num = 25)
+   ->  Bitmap Index Scan on idx_partial
+         Index Cond: (num = 25)
+(4 rows)
+
+ALTER INDEX idx_partial INVISIBLE;
+SELECT show_index_status('idx_partial');
+   show_index_status   
+-----------------------
+ (idx_partial,t,t,t,f)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE num = 25;
+              QUERY PLAN              
+--------------------------------------
+ Bitmap Heap Scan on index_test
+   Recheck Cond: (num = 25)
+   ->  Bitmap Index Scan on idx_multi
+         Index Cond: (num = 25)
+(4 rows)
+
+ALTER INDEX idx_partial VISIBLE;
+SELECT show_index_status('idx_partial');
+   show_index_status   
+-----------------------
+ (idx_partial,t,t,t,t)
+(1 row)
+
+-- 4. Expression index
+CREATE INDEX idx_expression ON index_test((lower(data)));
+SELECT show_index_status('idx_expression');
+    show_index_status     
+--------------------------
+ (idx_expression,t,t,t,t)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE lower(data) = 'data 500';
+                      QUERY PLAN                      
+------------------------------------------------------
+ Bitmap Heap Scan on index_test
+   Recheck Cond: (lower(data) = 'data 500'::text)
+   ->  Bitmap Index Scan on idx_expression
+         Index Cond: (lower(data) = 'data 500'::text)
+(4 rows)
+
+ALTER INDEX idx_expression INVISIBLE;
+SELECT show_index_status('idx_expression');
+    show_index_status     
+--------------------------
+ (idx_expression,t,t,t,f)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE lower(data) = 'data 500';
+                 QUERY PLAN                 
+--------------------------------------------
+ Seq Scan on index_test
+   Filter: (lower(data) = 'data 500'::text)
+(2 rows)
+
+ALTER INDEX idx_expression VISIBLE;
+SELECT show_index_status('idx_expression');
+    show_index_status     
+--------------------------
+ (idx_expression,t,t,t,t)
+(1 row)
+
+-- 5. GIN index
+CREATE INDEX idx_gin ON index_test USING gin(vector);
+SELECT show_index_status('idx_gin');
+ show_index_status 
+-------------------
+ (idx_gin,t,t,t,t)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE vector @> ARRAY[500];
+                     QUERY PLAN                     
+----------------------------------------------------
+ Bitmap Heap Scan on index_test
+   Recheck Cond: (vector @> '{500}'::integer[])
+   ->  Bitmap Index Scan on idx_gin
+         Index Cond: (vector @> '{500}'::integer[])
+(4 rows)
+
+ALTER INDEX idx_gin INVISIBLE;
+SELECT show_index_status('idx_gin');
+ show_index_status 
+-------------------
+ (idx_gin,t,t,t,f)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE vector @> ARRAY[500];
+                QUERY PLAN                
+------------------------------------------
+ Seq Scan on index_test
+   Filter: (vector @> '{500}'::integer[])
+(2 rows)
+
+ALTER INDEX idx_gin VISIBLE;
+SELECT show_index_status('idx_gin');
+ show_index_status 
+-------------------
+ (idx_gin,t,t,t,t)
+(1 row)
+
+-- 6. GiST index
+CREATE INDEX idx_gist ON index_test USING gist(range);
+SELECT show_index_status('idx_gist');
+ show_index_status  
+--------------------
+ (idx_gist,t,t,t,t)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE range && int4range(100, 110);
+                      QUERY PLAN                       
+-------------------------------------------------------
+ Bitmap Heap Scan on index_test
+   Recheck Cond: (range && '[100,110)'::int4range)
+   ->  Bitmap Index Scan on idx_gist
+         Index Cond: (range && '[100,110)'::int4range)
+(4 rows)
+
+ALTER INDEX idx_gist INVISIBLE;
+SELECT show_index_status('idx_gist');
+ show_index_status  
+--------------------
+ (idx_gist,t,t,t,f)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE range && int4range(100, 110);
+                 QUERY PLAN                  
+---------------------------------------------
+ Seq Scan on index_test
+   Filter: (range && '[100,110)'::int4range)
+(2 rows)
+
+ALTER INDEX idx_gist VISIBLE;
+SELECT show_index_status('idx_gist');
+ show_index_status  
+--------------------
+ (idx_gist,t,t,t,t)
+(1 row)
+
+-- 7. Covering index
+CREATE INDEX idx_covering ON index_test(num) INCLUDE (data);
+SELECT show_index_status('idx_covering');
+   show_index_status    
+------------------------
+ (idx_covering,t,t,t,t)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT num, data FROM index_test WHERE num = 50;
+               QUERY PLAN                
+-----------------------------------------
+ Bitmap Heap Scan on index_test
+   Recheck Cond: (num = 50)
+   ->  Bitmap Index Scan on idx_covering
+         Index Cond: (num = 50)
+(4 rows)
+
+ALTER INDEX idx_covering INVISIBLE;
+SELECT show_index_status('idx_covering');
+   show_index_status    
+------------------------
+ (idx_covering,t,t,t,f)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT num, data FROM index_test WHERE num = 50;
+              QUERY PLAN              
+--------------------------------------
+ Bitmap Heap Scan on index_test
+   Recheck Cond: (num = 50)
+   ->  Bitmap Index Scan on idx_multi
+         Index Cond: (num = 50)
+(4 rows)
+
+ALTER INDEX idx_covering VISIBLE;
+SELECT show_index_status('idx_covering');
+   show_index_status    
+------------------------
+ (idx_covering,t,t,t,t)
+(1 row)
+
+-- 8. Unique index
+CREATE UNIQUE INDEX idx_unique ON index_test(id, data);
+SELECT show_index_status('idx_unique');
+  show_index_status   
+----------------------
+ (idx_unique,t,t,t,t)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE id = 500 AND data = 'data 500';
+                        QUERY PLAN                        
+----------------------------------------------------------
+ Index Scan using idx_unique on index_test
+   Index Cond: ((id = 500) AND (data = 'data 500'::text))
+(2 rows)
+
+ALTER INDEX idx_unique INVISIBLE;
+SELECT show_index_status('idx_unique');
+  show_index_status   
+----------------------
+ (idx_unique,t,t,t,f)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE id = 500 AND data = 'data 500';
+                   QUERY PLAN                   
+------------------------------------------------
+ Index Scan using index_test_pkey on index_test
+   Index Cond: (id = 500)
+   Filter: (data = 'data 500'::text)
+(3 rows)
+
+ALTER INDEX idx_unique VISIBLE;
+SELECT show_index_status('idx_unique');
+  show_index_status   
+----------------------
+ (idx_unique,t,t,t,t)
+(1 row)
+
+-- 9. Function-based index
+CREATE INDEX idx_func ON index_test(get_data_length(data));
+SELECT show_index_status('idx_func');
+ show_index_status  
+--------------------
+ (idx_func,t,t,t,t)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE get_data_length(data) = 10;
+               QUERY PLAN                
+-----------------------------------------
+ Bitmap Heap Scan on index_test
+   Recheck Cond: (length(data) = 10)
+   ->  Bitmap Index Scan on idx_func
+         Index Cond: (length(data) = 10)
+(4 rows)
+
+ALTER INDEX idx_func INVISIBLE;
+SELECT show_index_status('idx_func');
+ show_index_status  
+--------------------
+ (idx_func,t,t,t,f)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE get_data_length(data) = 10;
+          QUERY PLAN           
+-------------------------------
+ Seq Scan on index_test
+   Filter: (length(data) = 10)
+(2 rows)
+
+ALTER INDEX idx_func VISIBLE;
+SELECT show_index_status('idx_func');
+ show_index_status  
+--------------------
+ (idx_func,t,t,t,t)
+(1 row)
+
+-- 10. Join index
+CREATE TABLE join_test (id INT PRIMARY KEY, ref_id INT);
+INSERT INTO join_test SELECT g, g % 100 FROM generate_series(1, 1000) g;
+CREATE INDEX idx_join ON join_test(ref_id);
+SELECT show_index_status('idx_join');
+ show_index_status  
+--------------------
+ (idx_join,t,t,t,t)
+(1 row)
+
+EXPLAIN (COSTS OFF)
+SELECT jt.id, it.data
+FROM join_test jt
+JOIN index_test it ON jt.ref_id = it.num
+WHERE jt.id BETWEEN 100 AND 200;
+                          QUERY PLAN                           
+---------------------------------------------------------------
+ Hash Join
+   Hash Cond: (it.num = jt.ref_id)
+   ->  Seq Scan on index_test it
+   ->  Hash
+         ->  Bitmap Heap Scan on join_test jt
+               Recheck Cond: ((id >= 100) AND (id <= 200))
+               ->  Bitmap Index Scan on join_test_pkey
+                     Index Cond: ((id >= 100) AND (id <= 200))
+(8 rows)
+
+-- Set all indexes to invisible to force seq scan
+ALTER INDEX idx_join INVISIBLE;
+ALTER INDEX join_test_pkey INVISIBLE;
+SELECT show_index_status('idx_join');
+ show_index_status  
+--------------------
+ (idx_join,t,t,t,f)
+(1 row)
+
+SELECT show_index_status('join_test_pkey');
+    show_index_status     
+--------------------------
+ (join_test_pkey,t,t,t,f)
+(1 row)
+
+EXPLAIN (COSTS OFF)
+SELECT jt.id, it.data
+FROM join_test jt
+JOIN index_test it ON jt.ref_id = it.num
+WHERE jt.id BETWEEN 100 AND 200;
+                     QUERY PLAN                      
+-----------------------------------------------------
+ Hash Join
+   Hash Cond: (it.num = jt.ref_id)
+   ->  Seq Scan on index_test it
+   ->  Hash
+         ->  Seq Scan on join_test jt
+               Filter: ((id >= 100) AND (id <= 200))
+(6 rows)
+
+ALTER INDEX idx_join VISIBLE;
+ALTER INDEX join_test_pkey VISIBLE;
+SELECT show_index_status('idx_join');
+ show_index_status  
+--------------------
+ (idx_join,t,t,t,t)
+(1 row)
+
+SELECT show_index_status('join_test_pkey');
+    show_index_status     
+--------------------------
+ (join_test_pkey,t,t,t,t)
+(1 row)
+
+-- Test REINDEX CONCURRENTLY
+REINDEX INDEX CONCURRENTLY idx_join;
+SELECT show_index_status('idx_join');
+ show_index_status  
+--------------------
+ (idx_join,t,t,t,t)
+(1 row)
+
+ALTER INDEX idx_join INVISIBLE;
+SELECT show_index_status('idx_join');
+ show_index_status  
+--------------------
+ (idx_join,t,t,t,f)
+(1 row)
+
+REINDEX INDEX CONCURRENTLY idx_join;
+SELECT show_index_status('idx_join');
+ show_index_status  
+--------------------
+ (idx_join,t,t,t,f)
+(1 row)
+
+SELECT pg_get_indexdef('idx_join'::regclass);
+                                   pg_get_indexdef                                   
+-------------------------------------------------------------------------------------
+ CREATE INDEX idx_join ON schema_to_reindex.join_test USING btree (ref_id) INVISIBLE
+(1 row)
+
+ALTER INDEX idx_join VISIBLE;
+SELECT pg_get_indexdef('idx_join'::regclass);
+                              pg_get_indexdef                              
+---------------------------------------------------------------------------
+ CREATE INDEX idx_join ON schema_to_reindex.join_test USING btree (ref_id)
+(1 row)
+
+-- Test index visibility with indcheckxmin being true
+CREATE TABLE indcheckxmin_test(id int PRIMARY KEY);
+INSERT INTO indcheckxmin_test VALUES (1), (2), (3);
+CREATE INDEX CONCURRENTLY idx_checkxmin ON indcheckxmin_test(id);
+BEGIN;
+-- Simulate indcheckxmin being true
+UPDATE pg_index SET indcheckxmin = true WHERE indexrelid = 'idx_checkxmin'::regclass;
+ALTER INDEX idx_checkxmin INVISIBLE;  -- expect fail
+ERROR:  cannot update index visibility while indcheckxmin is true
+HINT:  Wait for all transactions that might see inconsistent HOT chains to complete
+ROLLBACK;
+-- Test prepared statements with index visibility
+CREATE TABLE prep_idx_test (id int, data text);
+CREATE INDEX prep_idx1 ON prep_idx_test(data);
+INSERT INTO prep_idx_test SELECT g, 'data ' || g FROM generate_series(1,100) g;
+-- Test with visible index
+PREPARE idx_plan AS SELECT * FROM prep_idx_test WHERE data = $1;
+EXPLAIN (COSTS OFF) EXECUTE idx_plan('data 1');
+                 QUERY PLAN                  
+---------------------------------------------
+ Bitmap Heap Scan on prep_idx_test
+   Recheck Cond: (data = 'data 1'::text)
+   ->  Bitmap Index Scan on prep_idx1
+         Index Cond: (data = 'data 1'::text)
+(4 rows)
+
+EXECUTE idx_plan('data 1');
+ id |  data  
+----+--------
+  1 | data 1
+(1 row)
+
+-- Test with invisible index
+ALTER INDEX prep_idx1 INVISIBLE;
+EXPLAIN (COSTS OFF) EXECUTE idx_plan('data 1');
+            QUERY PLAN             
+-----------------------------------
+ Seq Scan on prep_idx_test
+   Filter: (data = 'data 1'::text)
+(2 rows)
+
+EXECUTE idx_plan('data 1');
+ id |  data  
+----+--------
+  1 | data 1
+(1 row)
+
+-- Test with use_invisible_index
+SET use_invisible_index TO on;
+EXPLAIN (COSTS OFF) EXECUTE idx_plan('data 1');
+                 QUERY PLAN                  
+---------------------------------------------
+ Bitmap Heap Scan on prep_idx_test
+   Recheck Cond: (data = 'data 1'::text)
+   ->  Bitmap Index Scan on prep_idx1
+         Index Cond: (data = 'data 1'::text)
+(4 rows)
+
+EXECUTE idx_plan('data 1');
+ id |  data  
+----+--------
+  1 | data 1
+(1 row)
+
+SET use_invisible_index TO off;
+-- Assert plan cache is reset and index is not used
+EXPLAIN (COSTS OFF) EXECUTE idx_plan('data 1');
+            QUERY PLAN             
+-----------------------------------
+ Seq Scan on prep_idx_test
+   Filter: (data = 'data 1'::text)
+(2 rows)
+
+-- Make index visible and test again
+ALTER INDEX prep_idx1 VISIBLE;
+EXPLAIN (COSTS OFF) EXECUTE idx_plan('data 1');
+                 QUERY PLAN                  
+---------------------------------------------
+ Bitmap Heap Scan on prep_idx_test
+   Recheck Cond: (data = 'data 1'::text)
+   ->  Bitmap Index Scan on prep_idx1
+         Index Cond: (data = 'data 1'::text)
+(4 rows)
+
+EXECUTE idx_plan('data 1');
+ id |  data  
+----+--------
+  1 | data 1
+(1 row)
+
+-- Test index visibility with partitioned tables
+CREATE TABLE part_tbl(id int, data text) PARTITION BY RANGE(id);
+CREATE TABLE part1 PARTITION OF part_tbl FOR VALUES FROM (1) TO (100);
+CREATE TABLE part2 PARTITION OF part_tbl FOR VALUES FROM (100) TO (200);
+INSERT INTO part_tbl
+SELECT g, 'data ' || g
+FROM generate_series(1, 199) g;
+CREATE INDEX idx_part_tbl ON part_tbl(data);
+SELECT c.relname, i.indisvisible
+FROM pg_index i
+JOIN pg_class c ON i.indexrelid = c.oid
+WHERE c.relname LIKE 'idx_part_tbl%'
+ORDER BY c.relname;
+   relname    | indisvisible 
+--------------+--------------
+ idx_part_tbl | t
+(1 row)
+
+-- Force use of indexes to avoid flaky test results
+SET enable_seqscan = off;
+EXPLAIN (COSTS OFF)
+SELECT * FROM part_tbl WHERE data = 'data 50';
+                        QUERY PLAN                         
+-----------------------------------------------------------
+ Append
+   ->  Index Scan using part1_data_idx on part1 part_tbl_1
+         Index Cond: (data = 'data 50'::text)
+   ->  Index Scan using part2_data_idx on part2 part_tbl_2
+         Index Cond: (data = 'data 50'::text)
+(5 rows)
+
+ALTER INDEX idx_part_tbl INVISIBLE;
+SELECT c.relname, i.indisvisible
+FROM pg_index i
+JOIN pg_class c ON i.indexrelid = c.oid
+WHERE c.relname LIKE 'idx_part_tbl%'
+ORDER BY c.relname;
+   relname    | indisvisible 
+--------------+--------------
+ idx_part_tbl | f
+(1 row)
+
+-- Check query plan after setting invisible (should use seq scan)
+EXPLAIN (COSTS OFF)
+SELECT * FROM part_tbl WHERE data = 'data 50';
+                QUERY PLAN                
+------------------------------------------
+ Append
+   ->  Seq Scan on part1 part_tbl_1
+         Disabled: true
+         Filter: (data = 'data 50'::text)
+   ->  Seq Scan on part2 part_tbl_2
+         Disabled: true
+         Filter: (data = 'data 50'::text)
+(7 rows)
+
+SET use_invisible_index TO on;
+EXPLAIN (COSTS OFF)
+SELECT * FROM part_tbl WHERE data = 'data 50';
+                        QUERY PLAN                         
+-----------------------------------------------------------
+ Append
+   ->  Index Scan using part1_data_idx on part1 part_tbl_1
+         Index Cond: (data = 'data 50'::text)
+   ->  Index Scan using part2_data_idx on part2 part_tbl_2
+         Index Cond: (data = 'data 50'::text)
+(5 rows)
+
+SET use_invisible_index TO off;
+EXPLAIN (COSTS OFF)
+SELECT * FROM part_tbl WHERE data = 'data 50';
+                QUERY PLAN                
+------------------------------------------
+ Append
+   ->  Seq Scan on part1 part_tbl_1
+         Disabled: true
+         Filter: (data = 'data 50'::text)
+   ->  Seq Scan on part2 part_tbl_2
+         Disabled: true
+         Filter: (data = 'data 50'::text)
+(7 rows)
+
+ALTER INDEX idx_part_tbl VISIBLE;
+SELECT c.relname, i.indisvisible
+FROM pg_index i
+JOIN pg_class c ON i.indexrelid = c.oid
+WHERE c.relname LIKE 'idx_part_tbl%'
+ORDER BY c.relname;
+   relname    | indisvisible 
+--------------+--------------
+ idx_part_tbl | t
+(1 row)
+
+EXPLAIN (COSTS OFF)
+SELECT * FROM part_tbl WHERE data = 'data 50';
+                        QUERY PLAN                         
+-----------------------------------------------------------
+ Append
+   ->  Index Scan using part1_data_idx on part1 part_tbl_1
+         Index Cond: (data = 'data 50'::text)
+   ->  Index Scan using part2_data_idx on part2 part_tbl_2
+         Index Cond: (data = 'data 50'::text)
+(5 rows)
+
+SET enable_seqscan = on;
+-- Test REINDEX maintains visibility setting
+ALTER INDEX idx_part_tbl INVISIBLE;
+REINDEX INDEX idx_part_tbl;
+SELECT c.relname, i.indisvisible
+FROM pg_index i
+JOIN pg_class c ON i.indexrelid = c.oid
+WHERE c.relname LIKE 'idx_part_tbl%'
+ORDER BY c.relname;
+   relname    | indisvisible 
+--------------+--------------
+ idx_part_tbl | f
+(1 row)
+
+-- Test that index visibility is preserved after ALTER TABLE
+CREATE TABLE vis_test(id INT PRIMARY KEY, data text);
+\d vis_test
+        Table "schema_to_reindex.vis_test"
+ Column |  Type   | Collation | Nullable | Default 
+--------+---------+-----------+----------+---------
+ id     | integer |           | not null | 
+ data   | text    |           |          | 
+Indexes:
+    "vis_test_pkey" PRIMARY KEY, btree (id)
+
+ALTER INDEX vis_test_pkey INVISIBLE;
+\d vis_test
+        Table "schema_to_reindex.vis_test"
+ Column |  Type   | Collation | Nullable | Default 
+--------+---------+-----------+----------+---------
+ id     | integer |           | not null | 
+ data   | text    |           |          | 
+Indexes:
+    "vis_test_pkey" PRIMARY KEY, btree (id) INVISIBLE
+
+ALTER TABLE vis_test ALTER COLUMN id SET DATA TYPE bigint;
+\d vis_test
+        Table "schema_to_reindex.vis_test"
+ Column |  Type  | Collation | Nullable | Default 
+--------+--------+-----------+----------+---------
+ id     | bigint |           | not null | 
+ data   | text   |           |          | 
+Indexes:
+    "vis_test_pkey" PRIMARY KEY, btree (id) INVISIBLE
+
+ALTER TABLE vis_test ALTER COLUMN id SET DATA TYPE int;
+\d vis_test
+        Table "schema_to_reindex.vis_test"
+ Column |  Type   | Collation | Nullable | Default 
+--------+---------+-----------+----------+---------
+ id     | integer |           | not null | 
+ data   | text    |           |          | 
+Indexes:
+    "vis_test_pkey" PRIMARY KEY, btree (id) INVISIBLE
+
+ALTER INDEX vis_test_pkey VISIBLE;
+\d vis_test
+        Table "schema_to_reindex.vis_test"
+ Column |  Type   | Collation | Nullable | Default 
+--------+---------+-----------+----------+---------
+ id     | integer |           | not null | 
+ data   | text    |           |          | 
+Indexes:
+    "vis_test_pkey" PRIMARY KEY, btree (id)
+
+-- Test CREATE INDEX with INVISIBLE option
+CREATE TABLE invis_test(id int, data text);
+INSERT INTO invis_test SELECT g, 'data ' || g FROM generate_series(1,100) g;
+CREATE INDEX idx_invis1 ON invis_test(data) INVISIBLE;
+\d invis_test
+       Table "schema_to_reindex.invis_test"
+ Column |  Type   | Collation | Nullable | Default 
+--------+---------+-----------+----------+---------
+ id     | integer |           |          | 
+ data   | text    |           |          | 
+Indexes:
+    "idx_invis1" btree (data) INVISIBLE
+
+\d idx_invis1
+Index "schema_to_reindex.idx_invis1"
+ Column | Type | Key? | Definition 
+--------+------+------+------------
+ data   | text | yes  | data
+btree, for table "schema_to_reindex.invis_test", invisible
+
+ALTER INDEX idx_invis1 VISIBLE;
+\d invis_test
+       Table "schema_to_reindex.invis_test"
+ Column |  Type   | Collation | Nullable | Default 
+--------+---------+-----------+----------+---------
+ id     | integer |           |          | 
+ data   | text    |           |          | 
+Indexes:
+    "idx_invis1" btree (data)
+
+\d idx_invis1
+Index "schema_to_reindex.idx_invis1"
+ Column | Type | Key? | Definition 
+--------+------+------+------------
+ data   | text | yes  | data
+btree, for table "schema_to_reindex.invis_test"
+
+-- Clean up
+DROP TABLE index_test;
+DROP TABLE join_test;
+DROP FUNCTION get_data_length;
+DROP FUNCTION show_index_status;
+DROP TABLE indcheckxmin_test CASCADE;
+DEALLOCATE idx_plan;
+DROP TABLE prep_idx_test;
+DROP TABLE part_tbl CASCADE;
+DROP TABLE vis_test;
+DROP TABLE invis_test;
 -- Failure for unauthorized user
 CREATE ROLE regress_reindexuser NOLOGIN;
 SET SESSION ROLE regress_reindexuser;
diff --git a/src/test/regress/sql/create_index.sql b/src/test/regress/sql/create_index.sql
index e21ff42651..b4bea3f9d9 100644
--- a/src/test/regress/sql/create_index.sql
+++ b/src/test/regress/sql/create_index.sql
@@ -1496,6 +1496,327 @@ END;
 -- concurrently
 REINDEX SCHEMA CONCURRENTLY schema_to_reindex;
 
+-- Test index visibility functionality
+
+CREATE TABLE index_test(
+    id INT PRIMARY KEY,
+    data TEXT,
+    num INT,
+    vector INT[],
+    range INT4RANGE
+);
+
+INSERT INTO index_test
+SELECT
+    g,
+    'data ' || g,
+    g % 100,
+    ARRAY[g, g+1, g+2],
+    int4range(g, g+10)
+FROM generate_series(1, 1000) g;
+
+-- Function for testing
+CREATE FUNCTION get_data_length(text) RETURNS INT AS $$
+    SELECT length($1);
+$$ LANGUAGE SQL IMMUTABLE;
+
+-- Helper function to show index status
+CREATE OR REPLACE FUNCTION show_index_status(index_name text)
+RETURNS TABLE (
+    indexrelid regclass,
+    indisvalid boolean,
+    indisready boolean,
+    indislive boolean,
+    indisvisible boolean
+) AS $$
+BEGIN
+    RETURN QUERY EXECUTE format('
+        SELECT indexrelid::regclass, indisvalid, indisready, indislive, indisvisible
+        FROM pg_index
+        WHERE indexrelid = %L::regclass', index_name);
+END;
+$$ LANGUAGE plpgsql;
+
+-- Create and test each index type
+-- 1. Basic single-column index
+CREATE INDEX idx_single ON index_test(data);
+SELECT show_index_status('idx_single');
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE data = 'data 500';
+ALTER INDEX idx_single INVISIBLE;
+SELECT show_index_status('idx_single');
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE data = 'data 500';
+ALTER INDEX idx_single VISIBLE;
+SELECT show_index_status('idx_single');
+
+-- 2. Multi-column index
+CREATE INDEX idx_multi ON index_test(num, data);
+SELECT show_index_status('idx_multi');
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE num = 50 AND data > 'data 500';
+ALTER INDEX idx_multi INVISIBLE;
+SELECT show_index_status('idx_multi');
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE num = 50 AND data > 'data 500';
+ALTER INDEX idx_multi VISIBLE;
+SELECT show_index_status('idx_multi');
+
+-- 3. Partial index
+CREATE INDEX idx_partial ON index_test(num) WHERE num < 50;
+SELECT show_index_status('idx_partial');
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE num = 25;
+ALTER INDEX idx_partial INVISIBLE;
+SELECT show_index_status('idx_partial');
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE num = 25;
+ALTER INDEX idx_partial VISIBLE;
+SELECT show_index_status('idx_partial');
+
+-- 4. Expression index
+CREATE INDEX idx_expression ON index_test((lower(data)));
+SELECT show_index_status('idx_expression');
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE lower(data) = 'data 500';
+ALTER INDEX idx_expression INVISIBLE;
+SELECT show_index_status('idx_expression');
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE lower(data) = 'data 500';
+ALTER INDEX idx_expression VISIBLE;
+SELECT show_index_status('idx_expression');
+
+-- 5. GIN index
+CREATE INDEX idx_gin ON index_test USING gin(vector);
+SELECT show_index_status('idx_gin');
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE vector @> ARRAY[500];
+ALTER INDEX idx_gin INVISIBLE;
+SELECT show_index_status('idx_gin');
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE vector @> ARRAY[500];
+ALTER INDEX idx_gin VISIBLE;
+SELECT show_index_status('idx_gin');
+
+-- 6. GiST index
+CREATE INDEX idx_gist ON index_test USING gist(range);
+SELECT show_index_status('idx_gist');
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE range && int4range(100, 110);
+ALTER INDEX idx_gist INVISIBLE;
+SELECT show_index_status('idx_gist');
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE range && int4range(100, 110);
+ALTER INDEX idx_gist VISIBLE;
+SELECT show_index_status('idx_gist');
+
+-- 7. Covering index
+CREATE INDEX idx_covering ON index_test(num) INCLUDE (data);
+SELECT show_index_status('idx_covering');
+EXPLAIN (COSTS OFF) SELECT num, data FROM index_test WHERE num = 50;
+ALTER INDEX idx_covering INVISIBLE;
+SELECT show_index_status('idx_covering');
+EXPLAIN (COSTS OFF) SELECT num, data FROM index_test WHERE num = 50;
+ALTER INDEX idx_covering VISIBLE;
+SELECT show_index_status('idx_covering');
+
+-- 8. Unique index
+CREATE UNIQUE INDEX idx_unique ON index_test(id, data);
+SELECT show_index_status('idx_unique');
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE id = 500 AND data = 'data 500';
+ALTER INDEX idx_unique INVISIBLE;
+SELECT show_index_status('idx_unique');
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE id = 500 AND data = 'data 500';
+ALTER INDEX idx_unique VISIBLE;
+SELECT show_index_status('idx_unique');
+
+-- 9. Function-based index
+CREATE INDEX idx_func ON index_test(get_data_length(data));
+SELECT show_index_status('idx_func');
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE get_data_length(data) = 10;
+ALTER INDEX idx_func INVISIBLE;
+SELECT show_index_status('idx_func');
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE get_data_length(data) = 10;
+ALTER INDEX idx_func VISIBLE;
+SELECT show_index_status('idx_func');
+
+-- 10. Join index
+CREATE TABLE join_test (id INT PRIMARY KEY, ref_id INT);
+INSERT INTO join_test SELECT g, g % 100 FROM generate_series(1, 1000) g;
+CREATE INDEX idx_join ON join_test(ref_id);
+SELECT show_index_status('idx_join');
+
+EXPLAIN (COSTS OFF)
+SELECT jt.id, it.data
+FROM join_test jt
+JOIN index_test it ON jt.ref_id = it.num
+WHERE jt.id BETWEEN 100 AND 200;
+
+-- Set all indexes to invisible to force seq scan
+ALTER INDEX idx_join INVISIBLE;
+ALTER INDEX join_test_pkey INVISIBLE;
+SELECT show_index_status('idx_join');
+SELECT show_index_status('join_test_pkey');
+
+EXPLAIN (COSTS OFF)
+SELECT jt.id, it.data
+FROM join_test jt
+JOIN index_test it ON jt.ref_id = it.num
+WHERE jt.id BETWEEN 100 AND 200;
+
+ALTER INDEX idx_join VISIBLE;
+ALTER INDEX join_test_pkey VISIBLE;
+SELECT show_index_status('idx_join');
+SELECT show_index_status('join_test_pkey');
+
+-- Test REINDEX CONCURRENTLY
+REINDEX INDEX CONCURRENTLY idx_join;
+SELECT show_index_status('idx_join');
+
+ALTER INDEX idx_join INVISIBLE;
+SELECT show_index_status('idx_join');
+REINDEX INDEX CONCURRENTLY idx_join;
+SELECT show_index_status('idx_join');
+
+SELECT pg_get_indexdef('idx_join'::regclass);
+ALTER INDEX idx_join VISIBLE;
+SELECT pg_get_indexdef('idx_join'::regclass);
+
+-- Test index visibility with indcheckxmin being true
+
+CREATE TABLE indcheckxmin_test(id int PRIMARY KEY);
+INSERT INTO indcheckxmin_test VALUES (1), (2), (3);
+CREATE INDEX CONCURRENTLY idx_checkxmin ON indcheckxmin_test(id);
+BEGIN;
+-- Simulate indcheckxmin being true
+UPDATE pg_index SET indcheckxmin = true WHERE indexrelid = 'idx_checkxmin'::regclass;
+ALTER INDEX idx_checkxmin INVISIBLE;  -- expect fail
+ROLLBACK;
+
+-- Test prepared statements with index visibility
+CREATE TABLE prep_idx_test (id int, data text);
+CREATE INDEX prep_idx1 ON prep_idx_test(data);
+INSERT INTO prep_idx_test SELECT g, 'data ' || g FROM generate_series(1,100) g;
+
+-- Test with visible index
+PREPARE idx_plan AS SELECT * FROM prep_idx_test WHERE data = $1;
+EXPLAIN (COSTS OFF) EXECUTE idx_plan('data 1');
+EXECUTE idx_plan('data 1');
+
+-- Test with invisible index
+ALTER INDEX prep_idx1 INVISIBLE;
+EXPLAIN (COSTS OFF) EXECUTE idx_plan('data 1');
+EXECUTE idx_plan('data 1');
+
+-- Test with use_invisible_index
+SET use_invisible_index TO on;
+EXPLAIN (COSTS OFF) EXECUTE idx_plan('data 1');
+EXECUTE idx_plan('data 1');
+SET use_invisible_index TO off;
+-- Assert plan cache is reset and index is not used
+EXPLAIN (COSTS OFF) EXECUTE idx_plan('data 1');
+
+-- Make index visible and test again
+ALTER INDEX prep_idx1 VISIBLE;
+EXPLAIN (COSTS OFF) EXECUTE idx_plan('data 1');
+EXECUTE idx_plan('data 1');
+
+-- Test index visibility with partitioned tables
+CREATE TABLE part_tbl(id int, data text) PARTITION BY RANGE(id);
+CREATE TABLE part1 PARTITION OF part_tbl FOR VALUES FROM (1) TO (100);
+CREATE TABLE part2 PARTITION OF part_tbl FOR VALUES FROM (100) TO (200);
+
+INSERT INTO part_tbl
+SELECT g, 'data ' || g
+FROM generate_series(1, 199) g;
+
+CREATE INDEX idx_part_tbl ON part_tbl(data);
+
+SELECT c.relname, i.indisvisible
+FROM pg_index i
+JOIN pg_class c ON i.indexrelid = c.oid
+WHERE c.relname LIKE 'idx_part_tbl%'
+ORDER BY c.relname;
+
+-- Force use of indexes to avoid flaky test results
+SET enable_seqscan = off;
+
+EXPLAIN (COSTS OFF)
+SELECT * FROM part_tbl WHERE data = 'data 50';
+
+ALTER INDEX idx_part_tbl INVISIBLE;
+
+SELECT c.relname, i.indisvisible
+FROM pg_index i
+JOIN pg_class c ON i.indexrelid = c.oid
+WHERE c.relname LIKE 'idx_part_tbl%'
+ORDER BY c.relname;
+
+-- Check query plan after setting invisible (should use seq scan)
+EXPLAIN (COSTS OFF)
+SELECT * FROM part_tbl WHERE data = 'data 50';
+
+SET use_invisible_index TO on;
+
+EXPLAIN (COSTS OFF)
+SELECT * FROM part_tbl WHERE data = 'data 50';
+
+SET use_invisible_index TO off;
+
+EXPLAIN (COSTS OFF)
+SELECT * FROM part_tbl WHERE data = 'data 50';
+
+ALTER INDEX idx_part_tbl VISIBLE;
+
+SELECT c.relname, i.indisvisible
+FROM pg_index i
+JOIN pg_class c ON i.indexrelid = c.oid
+WHERE c.relname LIKE 'idx_part_tbl%'
+ORDER BY c.relname;
+
+EXPLAIN (COSTS OFF)
+SELECT * FROM part_tbl WHERE data = 'data 50';
+
+SET enable_seqscan = on;
+
+-- Test REINDEX maintains visibility setting
+ALTER INDEX idx_part_tbl INVISIBLE;
+REINDEX INDEX idx_part_tbl;
+
+SELECT c.relname, i.indisvisible
+FROM pg_index i
+JOIN pg_class c ON i.indexrelid = c.oid
+WHERE c.relname LIKE 'idx_part_tbl%'
+ORDER BY c.relname;
+
+-- Test that index visibility is preserved after ALTER TABLE
+CREATE TABLE vis_test(id INT PRIMARY KEY, data text);
+\d vis_test
+
+ALTER INDEX vis_test_pkey INVISIBLE;
+\d vis_test
+
+ALTER TABLE vis_test ALTER COLUMN id SET DATA TYPE bigint;
+\d vis_test
+
+ALTER TABLE vis_test ALTER COLUMN id SET DATA TYPE int;
+\d vis_test
+
+ALTER INDEX vis_test_pkey VISIBLE;
+\d vis_test
+
+-- Test CREATE INDEX with INVISIBLE option
+CREATE TABLE invis_test(id int, data text);
+INSERT INTO invis_test SELECT g, 'data ' || g FROM generate_series(1,100) g;
+
+CREATE INDEX idx_invis1 ON invis_test(data) INVISIBLE;
+\d invis_test
+\d idx_invis1
+
+ALTER INDEX idx_invis1 VISIBLE;
+\d invis_test
+\d idx_invis1
+
+-- Clean up
+DROP TABLE index_test;
+DROP TABLE join_test;
+DROP FUNCTION get_data_length;
+DROP FUNCTION show_index_status;
+DROP TABLE indcheckxmin_test CASCADE;
+DEALLOCATE idx_plan;
+DROP TABLE prep_idx_test;
+DROP TABLE part_tbl CASCADE;
+DROP TABLE vis_test;
+DROP TABLE invis_test;
+
 -- Failure for unauthorized user
 CREATE ROLE regress_reindexuser NOLOGIN;
 SET SESSION ROLE regress_reindexuser;
-- 
2.39.5 (Apple Git-154)

#85Sami Imseih
samimseih@gmail.com
In reply to: Shayon Mukherjee (#84)
1 attachment(s)
Re: [PATCH] Re: Proposal to Enable/Disable Index using ALTER INDEX

Attached v16 with feedback and rebased.

Thanks, and I realized the original tab-complete I proposed
was not entirely correct. I fixed it and also shortened the
commit message.

--
Sami Imseih
Amazon Web Services (AWS)

Attachments:

v17-0001-Introduce-the-ability-to-set-index-visibility-us.patchapplication/octet-stream; name=v17-0001-Introduce-the-ability-to-set-index-visibility-us.patchDownload
From 7fdfc7176643c2d43af91582168e9e02fa55d877 Mon Sep 17 00:00:00 2001
From: Shayon Mukherjee <shayonj@gmail.com>
Date: Sun, 12 Jan 2025 14:34:48 -0500
Subject: [PATCH v17 1/1] Introduce the ability to set index visibility using
 ALTER INDEX

This patch introduces the ability to make an index INVISIBLE ( or VISIBLE )
to the planner, making the index not eligible for planning but will continue
to be maintained when the underlying data changes. This behavior is accomplished
by introducing new grammar ALTER INDEX ... VISIBLE|INVISIBLE and
CREATE INDEX ... VISIBLE|INVISIBLE.

Discussion: https://www.postgresql.org/message-id/flat/EF2313B8-A017-4869-9B7F-A24EDD8795DE%40gmail.com#dbe65017ffa7b65a4f3f29e64ed2fce5
---
 doc/src/sgml/catalogs.sgml                    |  11 +
 doc/src/sgml/config.sgml                      |  16 +
 doc/src/sgml/indices.sgml                     |  21 +
 doc/src/sgml/ref/alter_index.sgml             |  36 +
 doc/src/sgml/ref/create_index.sgml            |  29 +
 src/backend/bootstrap/bootparse.y             |   2 +
 src/backend/catalog/index.c                   |  31 +-
 src/backend/catalog/toasting.c                |   2 +-
 src/backend/commands/indexcmds.c              |   4 +
 src/backend/commands/tablecmds.c              |  92 +-
 src/backend/optimizer/util/plancat.c          |  30 +-
 src/backend/parser/gram.y                     |  56 +-
 src/backend/parser/parse_utilcmd.c            |   3 +
 src/backend/utils/adt/ruleutils.c             |   4 +
 src/backend/utils/cache/relcache.c            |   1 +
 src/backend/utils/misc/guc_tables.c           |  10 +
 src/backend/utils/misc/postgresql.conf.sample |   1 +
 src/bin/pg_dump/pg_dump.c                     |  21 +-
 src/bin/pg_dump/pg_dump.h                     |   2 +
 src/bin/pg_dump/t/002_pg_dump.pl              |  29 +
 src/bin/psql/describe.c                       |  15 +-
 src/bin/psql/tab-complete.in.c                |   6 +-
 src/include/catalog/index.h                   |   2 +-
 src/include/catalog/pg_index.h                |   2 +
 src/include/nodes/parsenodes.h                |   4 +
 src/include/optimizer/optimizer.h             |   5 +
 src/include/parser/kwlist.h                   |   2 +
 src/include/utils/guc_hooks.h                 |   1 +
 src/test/modules/test_ddl_deparse/Makefile    |   3 +-
 .../test_ddl_deparse/expected/alter_index.out |  29 +
 src/test/modules/test_ddl_deparse/meson.build |   1 +
 .../test_ddl_deparse/sql/alter_index.sql      |  18 +
 .../test_ddl_deparse/test_ddl_deparse.c       |   6 +
 src/test/regress/expected/create_index.out    | 795 ++++++++++++++++++
 src/test/regress/sql/create_index.sql         | 321 +++++++
 35 files changed, 1585 insertions(+), 26 deletions(-)
 create mode 100644 src/test/modules/test_ddl_deparse/expected/alter_index.out
 create mode 100644 src/test/modules/test_ddl_deparse/sql/alter_index.sql

diff --git a/doc/src/sgml/catalogs.sgml b/doc/src/sgml/catalogs.sgml
index cbd4e40a320..3307df883b3 100644
--- a/doc/src/sgml/catalogs.sgml
+++ b/doc/src/sgml/catalogs.sgml
@@ -4618,6 +4618,17 @@ SCRAM-SHA-256$<replaceable>&lt;iteration count&gt;</replaceable>:<replaceable>&l
        partial index.
       </para></entry>
      </row>
+
+     <row>
+      <entry role="catalog_table_entry"><para role="column_definition">
+       <structfield>indisvisible</structfield> <type>bool</type>
+      </para>
+      <para>
+       If true, the index is currently visible to the planner and may be used for queries.
+       If false, the index is invisible and may not be used for queries,
+       but is still updated when the table is modified. Default is true.
+      </para></entry>
+     </row>
     </tbody>
    </tgroup>
   </table>
diff --git a/doc/src/sgml/config.sgml b/doc/src/sgml/config.sgml
index a8542fe41ce..32087c07f99 100644
--- a/doc/src/sgml/config.sgml
+++ b/doc/src/sgml/config.sgml
@@ -5778,6 +5778,22 @@ ANY <replaceable class="parameter">num_sync</replaceable> ( <replaceable class="
       </listitem>
      </varlistentry>
 
+     <varlistentry id="guc-force-invisible-index" xreflabel="use_invisible_index">
+      <term><varname>use_invisible_index</varname> (<type>boolean</type>)
+      <indexterm>
+       <primary><varname>use_invisible_index</varname> configuration parameter</primary>
+      </indexterm>
+      </term>
+      <listitem>
+       <para>
+        Forces the query planner to consider indexes that have been marked as invisible using
+        <command>ALTER INDEX ... INVISIBLE</command>. This parameter is useful for selective
+        use of invisible indexes in specific application contexts. The default
+        is <literal>off</literal>.
+       </para>
+      </listitem>
+     </varlistentry>
+
      </variablelist>
      </sect2>
      <sect2 id="runtime-config-query-constants">
diff --git a/doc/src/sgml/indices.sgml b/doc/src/sgml/indices.sgml
index 9c4f76abf0d..97bb599a05d 100644
--- a/doc/src/sgml/indices.sgml
+++ b/doc/src/sgml/indices.sgml
@@ -1673,6 +1673,27 @@ CREATE INDEX test1c_content_y_index ON test1c (content COLLATE "y");
      <productname>PostgreSQL</productname> developers to examine the issue.
     </para>
    </listitem>
+
+   <listitem>
+    <para>
+     Invisible indexes provide a convenient way to experiment with indexes
+     without needing to fully drop and recreate them. You can create a new index as
+     invisible with <command>CREATE INDEX ... INVISIBLE</command> or mark
+     an existing index invisible with <command>ALTER INDEX ... INVISIBLE</command>.
+     When an index is invisible, the planner will ignore it by default.
+     To test the index's effect on performance, set the
+     <varname>use_invisible_index</varname> parameter to <literal>on</literal>.
+     This allows you to compare query performance with and without the index
+     before making it visible to all queries with
+     <command>ALTER INDEX ... VISIBLE</command>.
+    </para>
+    <para>
+     Similarly, before dropping an existing index that appears unused,
+     consider marking it invisible to verify that query performance doesn't
+     degrade. Check <structname>pg_stat_user_indexes</structname>.<structfield>idx_scan</structfield>
+     to identify potentially unused indexes.
+    </para>
+   </listitem>
   </itemizedlist>
  </sect1>
 </chapter>
diff --git a/doc/src/sgml/ref/alter_index.sgml b/doc/src/sgml/ref/alter_index.sgml
index 1d42d05d858..a49d28a52d5 100644
--- a/doc/src/sgml/ref/alter_index.sgml
+++ b/doc/src/sgml/ref/alter_index.sgml
@@ -31,6 +31,7 @@ ALTER INDEX [ IF EXISTS ] <replaceable class="parameter">name</replaceable> ALTE
     SET STATISTICS <replaceable class="parameter">integer</replaceable>
 ALTER INDEX ALL IN TABLESPACE <replaceable class="parameter">name</replaceable> [ OWNED BY <replaceable class="parameter">role_name</replaceable> [, ... ] ]
     SET TABLESPACE <replaceable class="parameter">new_tablespace</replaceable> [ NOWAIT ]
+ALTER INDEX [ IF EXISTS ] <replaceable class="parameter">name</replaceable> { VISIBLE | INVISIBLE }
 </synopsis>
  </refsynopsisdiv>
 
@@ -159,6 +160,27 @@ ALTER INDEX ALL IN TABLESPACE <replaceable class="parameter">name</replaceable>
     </listitem>
    </varlistentry>
 
+   <varlistentry>
+    <term><literal>VISIBLE</literal></term>
+    <listitem>
+     <para>
+      Make the specified index visible. The index will be used for query planning.
+     </para>
+    </listitem>
+   </varlistentry>
+
+   <varlistentry>
+    <term><literal>INVISIBLE</literal></term>
+    <listitem>
+     <para>
+      Make the specified index invisible. The index will not be used for queries.
+      This can be useful for testing query performance with and without specific
+      indexes. If performance degrades after making an index invisible, it can be easily
+      be made visible using <literal>VISIBLE</literal>.
+     </para>
+    </listitem>
+   </varlistentry>
+
   </variablelist>
   </para>
 
@@ -301,6 +323,20 @@ CREATE INDEX coord_idx ON measured (x, y, (z + t));
 ALTER INDEX coord_idx ALTER COLUMN 3 SET STATISTICS 1000;
 </programlisting></para>
 
+  <para>
+   To make an index visible:
+<programlisting>
+ALTER INDEX idx_name VISIBLE;
+</programlisting>
+  </para>
+
+  <para>
+   To make an index invisible:
+<programlisting>
+ALTER INDEX idx_name INVISIBLE;
+</programlisting>
+  </para>
+
  </refsect1>
 
  <refsect1>
diff --git a/doc/src/sgml/ref/create_index.sgml b/doc/src/sgml/ref/create_index.sgml
index 208389e8006..90d7d90a2bb 100644
--- a/doc/src/sgml/ref/create_index.sgml
+++ b/doc/src/sgml/ref/create_index.sgml
@@ -28,6 +28,7 @@ CREATE [ UNIQUE ] INDEX [ CONCURRENTLY ] [ [ IF NOT EXISTS ] <replaceable class=
     [ WITH ( <replaceable class="parameter">storage_parameter</replaceable> [= <replaceable class="parameter">value</replaceable>] [, ... ] ) ]
     [ TABLESPACE <replaceable class="parameter">tablespace_name</replaceable> ]
     [ WHERE <replaceable class="parameter">predicate</replaceable> ]
+    [ INVISIBLE ]
 </synopsis>
  </refsynopsisdiv>
 
@@ -380,6 +381,19 @@ CREATE [ UNIQUE ] INDEX [ CONCURRENTLY ] [ [ IF NOT EXISTS ] <replaceable class=
       </listitem>
      </varlistentry>
 
+    <varlistentry>
+      <term><literal>INVISIBLE</literal></term>
+      <listitem>
+       <para>
+        Creates the index in an invisible state (default visible). An invisible index is
+        not used by the query planner for queries, but it is still maintained
+        when the underlying table data changes. This can be useful when you want to create
+        an index without immediately impacting query planning, allowing you to make it
+        visible later at a more convenient time. The index can be made visible later
+        using <command>ALTER INDEX ... VISIBLE</command>.
+       </para>
+      </listitem>
+     </varlistentry>
     </variablelist>
 
   <refsect2 id="sql-createindex-storage-parameters" xreflabel="Index Storage Parameters">
@@ -701,6 +715,14 @@ Indexes:
     partitioned index is a metadata only operation.
    </para>
 
+  <para>
+   When creating an index with the <literal>INVISIBLE</literal> option, the index
+   will be created but not used for query planning. This can be useful for
+   preparing an index in advance of its use, or for testing purposes. The index
+   will still be maintained as the table is modified, so it can be made visible
+   later without needing to be rebuilt. By default all new indexes are visible.
+  </para>
+
   </refsect2>
  </refsect1>
 
@@ -980,6 +1002,13 @@ SELECT * FROM points
 CREATE INDEX CONCURRENTLY sales_quantity_index ON sales_table (quantity);
 </programlisting></para>
 
+  <para>
+   To create an index on the table <literal>test_table</literal> with the default
+   name, but have it initially invisible:
+<programlisting>
+CREATE INDEX ON test_table (col1) INVISIBLE;
+</programlisting>
+  </para>
  </refsect1>
 
  <refsect1>
diff --git a/src/backend/bootstrap/bootparse.y b/src/backend/bootstrap/bootparse.y
index 9833f52c1be..ea21511a205 100644
--- a/src/backend/bootstrap/bootparse.y
+++ b/src/backend/bootstrap/bootparse.y
@@ -303,6 +303,7 @@ Boot_DeclareIndexStmt:
 					stmt->concurrent = false;
 					stmt->if_not_exists = false;
 					stmt->reset_default_tblspc = false;
+					stmt->isvisible = true;
 
 					/* locks and races need not concern us in bootstrap mode */
 					relationId = RangeVarGetRelid(stmt->relation, NoLock,
@@ -356,6 +357,7 @@ Boot_DeclareUniqueIndexStmt:
 					stmt->concurrent = false;
 					stmt->if_not_exists = false;
 					stmt->reset_default_tblspc = false;
+					stmt->isvisible = true;
 
 					/* locks and races need not concern us in bootstrap mode */
 					relationId = RangeVarGetRelid(stmt->relation, NoLock,
diff --git a/src/backend/catalog/index.c b/src/backend/catalog/index.c
index 739a92bdcc1..2d8ceb60cec 100644
--- a/src/backend/catalog/index.c
+++ b/src/backend/catalog/index.c
@@ -119,7 +119,8 @@ static void UpdateIndexRelation(Oid indexoid, Oid heapoid,
 								bool isexclusion,
 								bool immediate,
 								bool isvalid,
-								bool isready);
+								bool isready,
+								bool isvisible);
 static void index_update_stats(Relation rel,
 							   bool hasindex,
 							   double reltuples);
@@ -571,7 +572,8 @@ UpdateIndexRelation(Oid indexoid,
 					bool isexclusion,
 					bool immediate,
 					bool isvalid,
-					bool isready)
+					bool isready,
+					bool isvisible)
 {
 	int2vector *indkey;
 	oidvector  *indcollation;
@@ -649,6 +651,7 @@ UpdateIndexRelation(Oid indexoid,
 	values[Anum_pg_index_indisready - 1] = BoolGetDatum(isready);
 	values[Anum_pg_index_indislive - 1] = BoolGetDatum(true);
 	values[Anum_pg_index_indisreplident - 1] = BoolGetDatum(false);
+	values[Anum_pg_index_indisvisible - 1] = BoolGetDatum(isvisible);
 	values[Anum_pg_index_indkey - 1] = PointerGetDatum(indkey);
 	values[Anum_pg_index_indcollation - 1] = PointerGetDatum(indcollation);
 	values[Anum_pg_index_indclass - 1] = PointerGetDatum(indclass);
@@ -714,6 +717,8 @@ UpdateIndexRelation(Oid indexoid,
  *			already exists.
  *		INDEX_CREATE_PARTITIONED:
  *			create a partitioned index (table must be partitioned)
+ *		INDEX_CREATE_VISIBLE:
+ *			create the index as visible to query planner
  * constr_flags: flags passed to index_constraint_create
  *		(only if INDEX_CREATE_ADD_CONSTRAINT is set)
  * allow_system_table_mods: allow table to be a system catalog
@@ -759,6 +764,7 @@ index_create(Relation heapRelation,
 	bool		invalid = (flags & INDEX_CREATE_INVALID) != 0;
 	bool		concurrent = (flags & INDEX_CREATE_CONCURRENT) != 0;
 	bool		partitioned = (flags & INDEX_CREATE_PARTITIONED) != 0;
+	bool		isvisible = (flags & INDEX_CREATE_VISIBLE) != 0;
 	char		relkind;
 	TransactionId relfrozenxid;
 	MultiXactId relminmxid;
@@ -1042,13 +1048,15 @@ index_create(Relation heapRelation,
 	 *	  (Or, could define a rule to maintain the predicate) --Nels, Feb '92
 	 * ----------------
 	 */
+
 	UpdateIndexRelation(indexRelationId, heapRelationId, parentIndexRelid,
 						indexInfo,
 						collationIds, opclassIds, coloptions,
 						isprimary, is_exclusion,
 						(constr_flags & INDEX_CONSTR_CREATE_DEFERRABLE) == 0,
 						!concurrent && !invalid,
-						!concurrent);
+						!concurrent,
+						isvisible);
 
 	/*
 	 * Register relcache invalidation on the indexes' heap relation, to
@@ -1317,6 +1325,8 @@ index_concurrently_create_copy(Relation heapRelation, Oid oldIndexId,
 	List	   *indexColNames = NIL;
 	List	   *indexExprs = NIL;
 	List	   *indexPreds = NIL;
+	Form_pg_index indexForm;
+	bits16		createFlags;
 
 	indexRelation = index_open(oldIndexId, RowExclusiveLock);
 
@@ -1344,6 +1354,9 @@ index_concurrently_create_copy(Relation heapRelation, Oid oldIndexId,
 											Anum_pg_index_indoption);
 	indcoloptions = (int2vector *) DatumGetPointer(colOptionDatum);
 
+	/* Get the visibility state of the original index */
+	indexForm = (Form_pg_index) GETSTRUCT(indexTuple);
+
 	/* Fetch reloptions of index if any */
 	classTuple = SearchSysCache1(RELOID, ObjectIdGetDatum(oldIndexId));
 	if (!HeapTupleIsValid(classTuple))
@@ -1435,6 +1448,16 @@ index_concurrently_create_copy(Relation heapRelation, Oid oldIndexId,
 		stattargets[i].isnull = isnull;
 	}
 
+	/*
+	 * Determine the create flags for the new index. We always use SKIP_BUILD
+	 * and CONCURRENT for concurrent reindexing. If the original index was
+	 * visible, we also set the VISIBLE flag to maintain the same state in the
+	 * new index.
+	 */
+	createFlags = INDEX_CREATE_SKIP_BUILD | INDEX_CREATE_CONCURRENT;
+	if (indexForm->indisvisible)
+		createFlags |= INDEX_CREATE_VISIBLE;
+
 	/*
 	 * Now create the new index.
 	 *
@@ -1458,7 +1481,7 @@ index_concurrently_create_copy(Relation heapRelation, Oid oldIndexId,
 							  indcoloptions->values,
 							  stattargets,
 							  reloptionsDatum,
-							  INDEX_CREATE_SKIP_BUILD | INDEX_CREATE_CONCURRENT,
+							  createFlags,
 							  0,
 							  true, /* allow table to be a system catalog? */
 							  false,	/* is_internal? */
diff --git a/src/backend/catalog/toasting.c b/src/backend/catalog/toasting.c
index 874a8fc89ad..7721d16fd30 100644
--- a/src/backend/catalog/toasting.c
+++ b/src/backend/catalog/toasting.c
@@ -325,7 +325,7 @@ create_toast_table(Relation rel, Oid toastOid, Oid toastIndexOid,
 				 BTREE_AM_OID,
 				 rel->rd_rel->reltablespace,
 				 collationIds, opclassIds, NULL, coloptions, NULL, (Datum) 0,
-				 INDEX_CREATE_IS_PRIMARY, 0, true, true, NULL);
+				 INDEX_CREATE_IS_PRIMARY | INDEX_CREATE_VISIBLE, 0, true, true, NULL);
 
 	table_close(toast_rel, NoLock);
 
diff --git a/src/backend/commands/indexcmds.c b/src/backend/commands/indexcmds.c
index 33c2106c17c..693f23e8d6d 100644
--- a/src/backend/commands/indexcmds.c
+++ b/src/backend/commands/indexcmds.c
@@ -1222,6 +1222,10 @@ DefineIndex(Oid tableId,
 		flags |= INDEX_CREATE_PARTITIONED;
 	if (stmt->primary)
 		flags |= INDEX_CREATE_IS_PRIMARY;
+	if (stmt->isvisible)
+		flags |= INDEX_CREATE_VISIBLE;
+	else
+		flags &= ~INDEX_CREATE_VISIBLE;
 
 	/*
 	 * If the table is partitioned, and recursion was declined but partitions
diff --git a/src/backend/commands/tablecmds.c b/src/backend/commands/tablecmds.c
index 686f1850cab..a9d4fd7002b 100644
--- a/src/backend/commands/tablecmds.c
+++ b/src/backend/commands/tablecmds.c
@@ -738,7 +738,8 @@ static List *GetParentedForeignKeyRefs(Relation partition);
 static void ATDetachCheckNoForeignKeyRefs(Relation partition);
 static char GetAttributeCompression(Oid atttypid, const char *compression);
 static char GetAttributeStorage(Oid atttypid, const char *storagemode);
-
+static void ATExecSetIndexVisibility(Relation rel, bool visible);
+static bool GetIndexVisibility(Oid indexOid);
 
 /* ----------------------------------------------------------------
  *		DefineRelation
@@ -4833,6 +4834,11 @@ AlterTableGetLockLevel(List *cmds)
 				cmd_lockmode = ShareUpdateExclusiveLock;
 				break;
 
+			case AT_SetIndexVisible:
+			case AT_SetIndexInvisible:
+				cmd_lockmode = ShareUpdateExclusiveLock;
+				break;
+
 			default:			/* oops */
 				elog(ERROR, "unrecognized alter table type: %d",
 					 (int) cmd->subtype);
@@ -5268,6 +5274,13 @@ ATPrepCmd(List **wqueue, Relation rel, AlterTableCmd *cmd,
 			/* No command-specific prep needed */
 			pass = AT_PASS_MISC;
 			break;
+		case AT_SetIndexVisible:
+		case AT_SetIndexInvisible:
+			ATSimplePermissions(cmd->subtype, rel, ATT_INDEX | ATT_PARTITIONED_INDEX);
+			ATSimpleRecursion(wqueue, rel, cmd, true, lockmode, context);
+			/* No command-specific prep needed */
+			pass = AT_PASS_MISC;
+			break;
 		default:				/* oops */
 			elog(ERROR, "unrecognized alter table type: %d",
 				 (int) cmd->subtype);
@@ -5664,6 +5677,12 @@ ATExecCmd(List **wqueue, AlteredTableInfo *tab,
 		case AT_DetachPartitionFinalize:
 			address = ATExecDetachPartitionFinalize(rel, ((PartitionCmd *) cmd->def)->name);
 			break;
+		case AT_SetIndexVisible:
+			ATExecSetIndexVisibility(rel, true);
+			break;
+		case AT_SetIndexInvisible:
+			ATExecSetIndexVisibility(rel, false);
+			break;
 		default:				/* oops */
 			elog(ERROR, "unrecognized alter table type: %d",
 				 (int) cmd->subtype);
@@ -6614,6 +6633,8 @@ alter_table_type_to_string(AlterTableType cmdtype)
 			return "DROP COLUMN";
 		case AT_AddIndex:
 		case AT_ReAddIndex:
+		case AT_SetIndexVisible:
+		case AT_SetIndexInvisible:
 			return NULL;		/* not real grammar */
 		case AT_AddConstraint:
 		case AT_ReAddConstraint:
@@ -15594,6 +15615,8 @@ ATPostAlterTypeParse(Oid oldId, Oid oldRelId, Oid refRelId, char *cmd,
 			stmt->reset_default_tblspc = true;
 			/* keep the index's comment */
 			stmt->idxcomment = GetComment(oldId, RelationRelationId, 0);
+			/* preserve the index's visibility status */
+			stmt->isvisible = GetIndexVisibility(oldId);
 
 			newcmd = makeNode(AlterTableCmd);
 			newcmd->subtype = AT_ReAddIndex;
@@ -15624,6 +15647,8 @@ ATPostAlterTypeParse(Oid oldId, Oid oldRelId, Oid refRelId, char *cmd,
 					indstmt->idxcomment = GetComment(indoid,
 													 RelationRelationId, 0);
 					indstmt->reset_default_tblspc = true;
+					/* preserve the index's visibility status */
+					indstmt->isvisible = GetIndexVisibility(indoid);
 
 					cmd->subtype = AT_ReAddIndex;
 					tab->subcmds[AT_PASS_OLD_INDEX] =
@@ -21981,3 +22006,68 @@ GetAttributeStorage(Oid atttypid, const char *storagemode)
 
 	return cstorage;
 }
+
+/*
+ * ATExecSetIndexVisibility
+ * Performs a catalog update to mark an index as visible or invisible in pg_index.
+ */
+static void
+ATExecSetIndexVisibility(Relation rel, bool visible)
+{
+	Oid			indexOid = RelationGetRelid(rel);
+	Oid			heapOid;
+	Relation	pg_index;
+	Relation	heapRel;
+	HeapTuple	indexTuple;
+	Form_pg_index indexForm;
+
+	heapOid = IndexGetRelation(indexOid, false);
+	heapRel = table_open(heapOid, AccessShareLock);
+	pg_index = table_open(IndexRelationId, RowExclusiveLock);
+
+	indexTuple = SearchSysCacheCopy1(INDEXRELID, ObjectIdGetDatum(indexOid));
+	if (!HeapTupleIsValid(indexTuple))
+		elog(ERROR, "cache lookup failed for index %u", indexOid);
+
+	indexForm = (Form_pg_index) GETSTRUCT(indexTuple);
+	if (indexForm->indcheckxmin)
+		ereport(ERROR,
+				errcode(ERRCODE_OBJECT_NOT_IN_PREREQUISITE_STATE),
+				errmsg("cannot update index visibility while indcheckxmin is true"),
+				errhint("Wait for all transactions that might see inconsistent HOT chains to complete"));
+
+	if (indexForm->indisvisible != visible)
+	{
+		indexForm->indisvisible = visible;
+		CatalogTupleUpdate(pg_index, &indexTuple->t_self, indexTuple);
+
+		CacheInvalidateRelcache(heapRel);
+		InvokeObjectPostAlterHook(IndexRelationId, indexOid, 0);
+		CommandCounterIncrement();
+	}
+
+	heap_freetuple(indexTuple);
+	table_close(pg_index, RowExclusiveLock);
+	table_close(heapRel, AccessShareLock);
+}
+
+/*
+* Get index visibility status from pg_index
+*/
+static bool
+GetIndexVisibility(Oid indexOid)
+{
+	HeapTuple	indexTuple;
+	Form_pg_index indexForm;
+	bool		isvisible;
+
+	indexTuple = SearchSysCache1(INDEXRELID, ObjectIdGetDatum(indexOid));
+	if (!HeapTupleIsValid(indexTuple))
+		elog(ERROR, "cache lookup failed for index %u", indexOid);
+
+	indexForm = (Form_pg_index) GETSTRUCT(indexTuple);
+	isvisible = indexForm->indisvisible;
+	ReleaseSysCache(indexTuple);
+
+	return isvisible;
+}
diff --git a/src/backend/optimizer/util/plancat.c b/src/backend/optimizer/util/plancat.c
index 59233b64730..6d938d35897 100644
--- a/src/backend/optimizer/util/plancat.c
+++ b/src/backend/optimizer/util/plancat.c
@@ -47,7 +47,9 @@
 #include "storage/bufmgr.h"
 #include "tcop/tcopprot.h"
 #include "utils/builtins.h"
+#include "utils/guc_hooks.h"
 #include "utils/lsyscache.h"
+#include "utils/plancache.h"
 #include "utils/partcache.h"
 #include "utils/rel.h"
 #include "utils/snapmgr.h"
@@ -55,6 +57,7 @@
 
 /* GUC parameter */
 int			constraint_exclusion = CONSTRAINT_EXCLUSION_PARTITION;
+bool		use_invisible_index = false;
 
 /* Hook for plugins to get control in get_relation_info() */
 get_relation_info_hook_type get_relation_info_hook = NULL;
@@ -256,13 +259,13 @@ get_relation_info(PlannerInfo *root, Oid relationObjectId, bool inhparent,
 			index = indexRelation->rd_index;
 
 			/*
-			 * Ignore invalid indexes, since they can't safely be used for
-			 * queries.  Note that this is OK because the data structure we
-			 * are constructing is only used by the planner --- the executor
-			 * still needs to insert into "invalid" indexes, if they're marked
-			 * indisready.
+			 * Skip invalid indexes, and invisible indexes unless
+			 * use_invisible_index is set. This is OK because the data
+			 * structure we are constructing is only used by the planner - the
+			 * executor still needs to insert into these indexes if they're
+			 * marked indisready.
 			 */
-			if (!index->indisvalid)
+			if (!index->indisvalid || (!index->indisvisible && !use_invisible_index))
 			{
 				index_close(indexRelation, NoLock);
 				continue;
@@ -2612,3 +2615,18 @@ set_baserel_partition_constraint(Relation relation, RelOptInfo *rel)
 		rel->partition_qual = partconstr;
 	}
 }
+
+/*
+ * assign_use_invisible_index
+ * GUC assign_hook for "use_invisible_index" GUC variable.
+ * Resets the plan cache when the value changes.
+ */
+void
+assign_use_invisible_index(bool newval, void *extra)
+{
+	if (use_invisible_index != newval)
+	{
+		use_invisible_index = newval;
+		ResetPlanCache();
+	}
+}
diff --git a/src/backend/parser/gram.y b/src/backend/parser/gram.y
index 3c4268b271a..9a1b23c6458 100644
--- a/src/backend/parser/gram.y
+++ b/src/backend/parser/gram.y
@@ -324,7 +324,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 %type <ival>	add_drop opt_asc_desc opt_nulls_order
 
 %type <node>	alter_table_cmd alter_type_cmd opt_collate_clause
-	   replica_identity partition_cmd index_partition_cmd
+	   replica_identity partition_cmd index_partition_cmd index_alter_cmd
 %type <list>	alter_table_cmds alter_type_cmds
 %type <list>    alter_identity_column_option_list
 %type <defelt>  alter_identity_column_option
@@ -491,6 +491,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 %type <boolean> opt_unique opt_verbose opt_full
 %type <boolean> opt_freeze opt_analyze opt_default
 %type <defelt>	opt_binary copy_delimiter
+%type <boolean>  opt_index_visibility
 
 %type <boolean> copy_from opt_program
 
@@ -733,7 +734,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 	IDENTITY_P IF_P ILIKE IMMEDIATE IMMUTABLE IMPLICIT_P IMPORT_P IN_P INCLUDE
 	INCLUDING INCREMENT INDENT INDEX INDEXES INHERIT INHERITS INITIALLY INLINE_P
 	INNER_P INOUT INPUT_P INSENSITIVE INSERT INSTEAD INT_P INTEGER
-	INTERSECT INTERVAL INTO INVOKER IS ISNULL ISOLATION
+	INTERSECT INTERVAL INTO INVISIBLE INVOKER IS ISNULL ISOLATION
 
 	JOIN JSON JSON_ARRAY JSON_ARRAYAGG JSON_EXISTS JSON_OBJECT JSON_OBJECTAGG
 	JSON_QUERY JSON_SCALAR JSON_SERIALIZE JSON_TABLE JSON_VALUE
@@ -784,7 +785,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 	UNLISTEN UNLOGGED UNTIL UPDATE USER USING
 
 	VACUUM VALID VALIDATE VALIDATOR VALUE_P VALUES VARCHAR VARIADIC VARYING
-	VERBOSE VERSION_P VIEW VIEWS VIRTUAL VOLATILE
+	VERBOSE VERSION_P VIEW VIEWS VIRTUAL VISIBLE VOLATILE
 
 	WHEN WHERE WHITESPACE_P WINDOW WITH WITHIN WITHOUT WORK WRAPPER WRITE
 
@@ -2157,6 +2158,24 @@ AlterTableStmt:
 					n->nowait = $13;
 					$$ = (Node *) n;
 				}
+		| ALTER INDEX qualified_name index_alter_cmd
+				{
+					AlterTableStmt *n = makeNode(AlterTableStmt);
+					n->relation = $3;
+					n->cmds = list_make1($4);
+					n->objtype = OBJECT_INDEX;
+					n->missing_ok = false;
+					$$ = (Node *) n;
+				}
+		| ALTER INDEX IF_P EXISTS qualified_name index_alter_cmd
+				{
+					AlterTableStmt *n = makeNode(AlterTableStmt);
+					n->relation = $5;
+					n->cmds = list_make1($6);
+					n->objtype = OBJECT_INDEX;
+					n->missing_ok = true;
+					$$ = (Node *) n;
+				}
 		|	ALTER INDEX qualified_name alter_table_cmds
 				{
 					AlterTableStmt *n = makeNode(AlterTableStmt);
@@ -2382,6 +2401,21 @@ index_partition_cmd:
 				}
 		;
 
+index_alter_cmd:
+		/* ALTER INDEX <name> VISIBLE|INVISIBLE */
+		VISIBLE
+			{
+				AlterTableCmd *n = makeNode(AlterTableCmd);
+				n->subtype = AT_SetIndexVisible;
+				$$ = (Node *) n;
+			}
+		| INVISIBLE
+			{
+				AlterTableCmd *n = makeNode(AlterTableCmd);
+				n->subtype = AT_SetIndexInvisible;
+				$$ = (Node *) n;
+			}
+		;
 alter_table_cmd:
 			/* ALTER TABLE <name> ADD <coldef> */
 			ADD_P columnDef
@@ -8190,7 +8224,7 @@ defacl_privilege_target:
 
 IndexStmt:	CREATE opt_unique INDEX opt_concurrently opt_single_name
 			ON relation_expr access_method_clause '(' index_params ')'
-			opt_include opt_unique_null_treatment opt_reloptions OptTableSpace where_clause
+			opt_include opt_unique_null_treatment opt_reloptions OptTableSpace where_clause opt_index_visibility
 				{
 					IndexStmt *n = makeNode(IndexStmt);
 
@@ -8205,6 +8239,7 @@ IndexStmt:	CREATE opt_unique INDEX opt_concurrently opt_single_name
 					n->options = $14;
 					n->tableSpace = $15;
 					n->whereClause = $16;
+					n->isvisible = $17;
 					n->excludeOpNames = NIL;
 					n->idxcomment = NULL;
 					n->indexOid = InvalidOid;
@@ -8222,7 +8257,7 @@ IndexStmt:	CREATE opt_unique INDEX opt_concurrently opt_single_name
 				}
 			| CREATE opt_unique INDEX opt_concurrently IF_P NOT EXISTS name
 			ON relation_expr access_method_clause '(' index_params ')'
-			opt_include opt_unique_null_treatment opt_reloptions OptTableSpace where_clause
+			opt_include opt_unique_null_treatment opt_reloptions OptTableSpace where_clause opt_index_visibility
 				{
 					IndexStmt *n = makeNode(IndexStmt);
 
@@ -8237,6 +8272,7 @@ IndexStmt:	CREATE opt_unique INDEX opt_concurrently opt_single_name
 					n->options = $17;
 					n->tableSpace = $18;
 					n->whereClause = $19;
+					n->isvisible = $20;
 					n->excludeOpNames = NIL;
 					n->idxcomment = NULL;
 					n->indexOid = InvalidOid;
@@ -8259,6 +8295,12 @@ opt_unique:
 			| /*EMPTY*/								{ $$ = false; }
 		;
 
+opt_index_visibility:
+			VISIBLE                       { $$ = true; }
+			| INVISIBLE                   { $$ = false; }
+			| /*EMPTY*/                   { $$ = true; }
+		;
+
 access_method_clause:
 			USING name								{ $$ = $2; }
 			| /*EMPTY*/								{ $$ = DEFAULT_INDEX_TYPE; }
@@ -17836,6 +17878,7 @@ unreserved_keyword:
 			| INSENSITIVE
 			| INSERT
 			| INSTEAD
+			| INVISIBLE
 			| INVOKER
 			| ISOLATION
 			| KEEP
@@ -18022,6 +18065,7 @@ unreserved_keyword:
 			| VIEW
 			| VIEWS
 			| VIRTUAL
+			| VISIBLE
 			| VOLATILE
 			| WHITESPACE_P
 			| WITHIN
@@ -18431,6 +18475,7 @@ bare_label_keyword:
 			| INT_P
 			| INTEGER
 			| INTERVAL
+			| INVISIBLE
 			| INVOKER
 			| IS
 			| ISOLATION
@@ -18679,6 +18724,7 @@ bare_label_keyword:
 			| VIEW
 			| VIEWS
 			| VIRTUAL
+			| VISIBLE
 			| VOLATILE
 			| WHEN
 			| WHITESPACE_P
diff --git a/src/backend/parser/parse_utilcmd.c b/src/backend/parser/parse_utilcmd.c
index 62015431fdf..0619833c09c 100644
--- a/src/backend/parser/parse_utilcmd.c
+++ b/src/backend/parser/parse_utilcmd.c
@@ -1745,6 +1745,7 @@ generateClonedIndexStmt(RangeVar *heapRel, Relation source_idx,
 	index->concurrent = false;
 	index->if_not_exists = false;
 	index->reset_default_tblspc = false;
+	index->isvisible = idxrec->indisvisible;
 
 	/*
 	 * We don't try to preserve the name of the source index; instead, just
@@ -2366,6 +2367,8 @@ transformIndexConstraint(Constraint *constraint, CreateStmtContext *cxt)
 	index->concurrent = false;
 	index->if_not_exists = false;
 	index->reset_default_tblspc = constraint->reset_default_tblspc;
+	/* Ensure indexes for constraints are created as visible by default */
+	index->isvisible = true;
 
 	/*
 	 * If it's ALTER TABLE ADD CONSTRAINT USING INDEX, look up the index and
diff --git a/src/backend/utils/adt/ruleutils.c b/src/backend/utils/adt/ruleutils.c
index 9e90acedb91..199781c1ab6 100644
--- a/src/backend/utils/adt/ruleutils.c
+++ b/src/backend/utils/adt/ruleutils.c
@@ -1565,6 +1565,10 @@ pg_get_indexdef_worker(Oid indexrelid, int colno,
 			else
 				appendStringInfo(&buf, " WHERE %s", str);
 		}
+
+		/* Add INVISIBLE clause if the index is invisible */
+		if (!idxrec->indisvisible)
+			appendStringInfoString(&buf, " INVISIBLE");
 	}
 
 	/* Clean up */
diff --git a/src/backend/utils/cache/relcache.c b/src/backend/utils/cache/relcache.c
index 2905ae86a20..b1d9dd769ca 100644
--- a/src/backend/utils/cache/relcache.c
+++ b/src/backend/utils/cache/relcache.c
@@ -2344,6 +2344,7 @@ RelationReloadIndexInfo(Relation relation)
 		relation->rd_index->indisready = index->indisready;
 		relation->rd_index->indislive = index->indislive;
 		relation->rd_index->indisreplident = index->indisreplident;
+		relation->rd_index->indisvisible = index->indisvisible;
 
 		/* Copy xmin too, as that is needed to make sense of indcheckxmin */
 		HeapTupleHeaderSetXmin(relation->rd_indextuple->t_data,
diff --git a/src/backend/utils/misc/guc_tables.c b/src/backend/utils/misc/guc_tables.c
index f596fda568c..902af281058 100644
--- a/src/backend/utils/misc/guc_tables.c
+++ b/src/backend/utils/misc/guc_tables.c
@@ -2130,6 +2130,16 @@ struct config_bool ConfigureNamesBool[] =
 		true,
 		NULL, NULL, NULL
 	},
+	{
+		{"use_invisible_index", PGC_USERSET, QUERY_TUNING_OTHER,
+			gettext_noop("Forces the planner to consider invisible indexes."),
+			NULL,
+			GUC_EXPLAIN
+		},
+		&use_invisible_index,
+		false,
+		NULL, assign_use_invisible_index, NULL
+	},
 
 	/* End-of-list marker */
 	{
diff --git a/src/backend/utils/misc/postgresql.conf.sample b/src/backend/utils/misc/postgresql.conf.sample
index 25fe90a430f..b1c15a7fd8a 100644
--- a/src/backend/utils/misc/postgresql.conf.sample
+++ b/src/backend/utils/misc/postgresql.conf.sample
@@ -428,6 +428,7 @@
 #enable_group_by_reordering = on
 #enable_distinct_reordering = on
 #enable_self_join_elimination = on
+#use_invisible_index = off		# forces planner to consider invisible indexes
 
 # - Planner Cost Constants -
 
diff --git a/src/bin/pg_dump/pg_dump.c b/src/bin/pg_dump/pg_dump.c
index 25264f8c9fb..aed8461f7ab 100644
--- a/src/bin/pg_dump/pg_dump.c
+++ b/src/bin/pg_dump/pg_dump.c
@@ -7647,7 +7647,8 @@ getIndexes(Archive *fout, TableInfo tblinfo[], int numTables)
 				i_tablespace,
 				i_indreloptions,
 				i_indstatcols,
-				i_indstatvals;
+				i_indstatvals,
+				i_indisvisible;
 
 	/*
 	 * We want to perform just one query against pg_index.  However, we
@@ -7690,7 +7691,7 @@ getIndexes(Archive *fout, TableInfo tblinfo[], int numTables)
 
 	appendPQExpBufferStr(query,
 						 "pg_catalog.pg_get_indexdef(i.indexrelid) AS indexdef, "
-						 "i.indkey, i.indisclustered, "
+						 "i.indkey, i.indisclustered, i.indisvisible, "
 						 "c.contype, c.conname, "
 						 "c.condeferrable, c.condeferred, "
 						 "c.tableoid AS contableoid, "
@@ -7712,6 +7713,13 @@ getIndexes(Archive *fout, TableInfo tblinfo[], int numTables)
 		appendPQExpBufferStr(query,
 							 "false AS indisreplident, ");
 
+	if (fout->remoteVersion >= 180000)
+		appendPQExpBufferStr(query,
+							 "i.indisvisible, ");
+	else
+		appendPQExpBufferStr(query,
+							 "true AS indisvisible, ");
+
 	if (fout->remoteVersion >= 110000)
 		appendPQExpBufferStr(query,
 							 "inh.inhparent AS parentidx, "
@@ -7826,6 +7834,7 @@ getIndexes(Archive *fout, TableInfo tblinfo[], int numTables)
 	i_indreloptions = PQfnumber(res, "indreloptions");
 	i_indstatcols = PQfnumber(res, "indstatcols");
 	i_indstatvals = PQfnumber(res, "indstatvals");
+	i_indisvisible = PQfnumber(res, "indisvisible");
 
 	indxinfo = (IndxInfo *) pg_malloc(ntups * sizeof(IndxInfo));
 
@@ -7916,7 +7925,7 @@ getIndexes(Archive *fout, TableInfo tblinfo[], int numTables)
 								  &indAttNames, &nindAttNames))
 					pg_fatal("could not parse %s array", "indattnames");
 			}
-
+			indxinfo[j].indisvisible = (PQgetvalue(res, j, i_indisvisible)[0] == 't');
 			relstats = getRelationStatistics(fout, &indxinfo[j].dobj, relpages,
 											 PQgetvalue(res, j, i_reltuples),
 											 relallvisible, relallfrozen, indexkind,
@@ -18217,6 +18226,12 @@ dumpConstraint(Archive *fout, const ConstraintInfo *coninfo)
 			}
 
 			appendPQExpBufferStr(q, ";\n");
+
+			if (!indxinfo->indisvisible)
+			{
+				appendPQExpBuffer(q, "ALTER INDEX %s INVISIBLE;\n",
+								  fmtQualifiedDumpable(indxinfo));
+			}
 		}
 
 		/*
diff --git a/src/bin/pg_dump/pg_dump.h b/src/bin/pg_dump/pg_dump.h
index b426b5e4736..55d0203df37 100644
--- a/src/bin/pg_dump/pg_dump.h
+++ b/src/bin/pg_dump/pg_dump.h
@@ -427,6 +427,8 @@ typedef struct _indxInfo
 
 	/* if there is an associated constraint object, its dumpId: */
 	DumpId		indexconstraint;
+
+	bool		indisvisible;
 } IndxInfo;
 
 typedef struct _indexAttachInfo
diff --git a/src/bin/pg_dump/t/002_pg_dump.pl b/src/bin/pg_dump/t/002_pg_dump.pl
index 6c03eca8e50..4bc579eb492 100644
--- a/src/bin/pg_dump/t/002_pg_dump.pl
+++ b/src/bin/pg_dump/t/002_pg_dump.pl
@@ -2185,6 +2185,35 @@ my %tests = (
 		like => {},
 	},
 
+	'ALTER TABLE ONLY test_table ADD CONSTRAINT ... PRIMARY KEY INVISIBLE' => {
+		create_order => 97,
+		create_sql => 'CREATE TABLE dump_test.test_table_invisible (
+					   id int PRIMARY KEY
+					  );
+					  ALTER INDEX dump_test.test_table_invisible_pkey INVISIBLE;',
+		regexp => qr/^
+			\QALTER TABLE ONLY dump_test.test_table_invisible\E\n\s+
+			\QADD CONSTRAINT test_table_invisible_pkey PRIMARY KEY (id);\E\n
+			\QALTER INDEX dump_test.test_table_invisible_pkey INVISIBLE;\E
+			/xm,
+		like => { %full_runs, %dump_test_schema_runs, section_post_data => 1 },
+		unlike => { exclude_dump_test_schema => 1, only_dump_measurement => 1 },
+	},
+
+	'CREATE INDEX ... INVISIBLE' => {
+		create_order => 98,
+		create_sql => 'CREATE TABLE dump_test.test_table_mixed_indexes (
+					   id int,
+					   value int
+					  );
+					  CREATE INDEX idx_visible ON dump_test.test_table_mixed_indexes(value);
+					  CREATE UNIQUE INDEX idx_invisible ON dump_test.test_table_mixed_indexes(value) INVISIBLE;
+					  ALTER INDEX dump_test.idx_invisible INVISIBLE;',
+		regexp => qr/CREATE UNIQUE INDEX idx_invisible ON dump_test\.test_table_mixed_indexes USING btree \(value\) INVISIBLE;/m,
+		like => { %full_runs, %dump_test_schema_runs, section_post_data => 1 },
+		unlike => { exclude_dump_test_schema => 1, only_dump_measurement => 1 },
+	},
+
 	'CREATE AGGREGATE dump_test.newavg' => {
 		create_order => 25,
 		create_sql => 'CREATE AGGREGATE dump_test.newavg (
diff --git a/src/bin/psql/describe.c b/src/bin/psql/describe.c
index 1d08268393e..bdb7397814c 100644
--- a/src/bin/psql/describe.c
+++ b/src/bin/psql/describe.c
@@ -2329,6 +2329,11 @@ describeOneTableDetails(const char *schemaname,
 		else
 			appendPQExpBufferStr(&buf, "false AS indnullsnotdistinct,\n");
 
+		if (pset.sversion >= 180000)
+			appendPQExpBufferStr(&buf, "i.indisvisible,\n");
+		else
+			appendPQExpBufferStr(&buf, "true AS indisvisible,\n");
+
 		appendPQExpBuffer(&buf, "  a.amname, c2.relname, "
 						  "pg_catalog.pg_get_expr(i.indpred, i.indrelid, true)\n"
 						  "FROM pg_catalog.pg_index i, pg_catalog.pg_class c, pg_catalog.pg_class c2, pg_catalog.pg_am a\n"
@@ -2354,9 +2359,10 @@ describeOneTableDetails(const char *schemaname,
 			char	   *deferred = PQgetvalue(result, 0, 5);
 			char	   *indisreplident = PQgetvalue(result, 0, 6);
 			char	   *indnullsnotdistinct = PQgetvalue(result, 0, 7);
-			char	   *indamname = PQgetvalue(result, 0, 8);
-			char	   *indtable = PQgetvalue(result, 0, 9);
-			char	   *indpred = PQgetvalue(result, 0, 10);
+			char	   *indisvisible = PQgetvalue(result, 0, 8);
+			char	   *indamname = PQgetvalue(result, 0, 9);
+			char	   *indtable = PQgetvalue(result, 0, 10);
+			char	   *indpred = PQgetvalue(result, 0, 11);
 
 			if (strcmp(indisprimary, "t") == 0)
 				printfPQExpBuffer(&tmpbuf, _("primary key, "));
@@ -2393,6 +2399,9 @@ describeOneTableDetails(const char *schemaname,
 			if (strcmp(indisreplident, "t") == 0)
 				appendPQExpBufferStr(&tmpbuf, _(", replica identity"));
 
+			if (strcmp(indisvisible, "t") != 0)
+				appendPQExpBufferStr(&tmpbuf, _(", invisible"));
+
 			printTableAddFooter(&cont, tmpbuf.data);
 
 			/*
diff --git a/src/bin/psql/tab-complete.in.c b/src/bin/psql/tab-complete.in.c
index c916b9299a8..8bafcb07407 100644
--- a/src/bin/psql/tab-complete.in.c
+++ b/src/bin/psql/tab-complete.in.c
@@ -2419,7 +2419,8 @@ match_previous_words(int pattern_id,
 	else if (Matches("ALTER", "INDEX", MatchAny))
 		COMPLETE_WITH("ALTER COLUMN", "OWNER TO", "RENAME TO", "SET",
 					  "RESET", "ATTACH PARTITION",
-					  "DEPENDS ON EXTENSION", "NO DEPENDS ON EXTENSION");
+					  "DEPENDS ON EXTENSION", "NO DEPENDS ON EXTENSION",
+					  "INVISIBLE", "VISIBLE");
 	else if (Matches("ALTER", "INDEX", MatchAny, "ATTACH"))
 		COMPLETE_WITH("PARTITION");
 	else if (Matches("ALTER", "INDEX", MatchAny, "ATTACH", "PARTITION"))
@@ -3433,6 +3434,9 @@ match_previous_words(int pattern_id,
 			 !TailMatches("POLICY", MatchAny, MatchAny, MatchAny, MatchAny, MatchAny) &&
 			 !TailMatches("FOR", MatchAny, MatchAny, MatchAny))
 		COMPLETE_WITH("(");
+	else if (TailMatches("INDEX|CONCURRENTLY", "ON", MatchAny, "USING", MatchAny, "(*)") ||
+			 TailMatches("INDEX|CONCURRENTLY", "ON", MatchAny, "(*)"))
+		COMPLETE_WITH("VISIBLE", "INVISIBLE");
 
 	/* CREATE OR REPLACE */
 	else if (Matches("CREATE", "OR"))
diff --git a/src/include/catalog/index.h b/src/include/catalog/index.h
index 4daa8bef5ee..75bef5bd88e 100644
--- a/src/include/catalog/index.h
+++ b/src/include/catalog/index.h
@@ -65,6 +65,7 @@ extern void index_check_primary_key(Relation heapRel,
 #define	INDEX_CREATE_IF_NOT_EXISTS			(1 << 4)
 #define	INDEX_CREATE_PARTITIONED			(1 << 5)
 #define INDEX_CREATE_INVALID				(1 << 6)
+#define INDEX_CREATE_VISIBLE				(1 << 7)
 
 extern Oid	index_create(Relation heapRelation,
 						 const char *indexRelationName,
@@ -175,7 +176,6 @@ extern void RestoreReindexState(const void *reindexstate);
 
 extern void IndexSetParentIndex(Relation partitionIdx, Oid parentOid);
 
-
 /*
  * itemptr_encode - Encode ItemPointer as int64/int8
  *
diff --git a/src/include/catalog/pg_index.h b/src/include/catalog/pg_index.h
index 4392b9d221d..ec8e5dc4bfa 100644
--- a/src/include/catalog/pg_index.h
+++ b/src/include/catalog/pg_index.h
@@ -44,6 +44,8 @@ CATALOG(pg_index,2610,IndexRelationId) BKI_SCHEMA_MACRO
 	bool		indisready;		/* is this index ready for inserts? */
 	bool		indislive;		/* is this index alive at all? */
 	bool		indisreplident; /* is this index the identity for replication? */
+	bool		indisvisible BKI_DEFAULT(t);	/* is this index visible for
+												 * use by queries? */
 
 	/* variable-length fields start here, but we allow direct access to indkey */
 	int2vector	indkey BKI_FORCE_NOT_NULL;	/* column numbers of indexed cols,
diff --git a/src/include/nodes/parsenodes.h b/src/include/nodes/parsenodes.h
index 4610fc61293..92a14b82f59 100644
--- a/src/include/nodes/parsenodes.h
+++ b/src/include/nodes/parsenodes.h
@@ -2472,6 +2472,8 @@ typedef enum AlterTableType
 	AT_SetIdentity,				/* SET identity column options */
 	AT_DropIdentity,			/* DROP IDENTITY */
 	AT_ReAddStatistics,			/* internal to commands/tablecmds.c */
+	AT_SetIndexVisible,			/* Set INDEX visible */
+	AT_SetIndexInvisible,		/* Set INDEX invisible */
 } AlterTableType;
 
 typedef struct AlterTableCmd	/* one subcommand of an ALTER TABLE */
@@ -3470,6 +3472,8 @@ typedef struct IndexStmt
 	bool		if_not_exists;	/* just do nothing if index already exists? */
 	bool		reset_default_tblspc;	/* reset default_tablespace prior to
 										 * executing */
+	bool		isvisible;		/* true if VISIBLE (default), false if
+								 * INVISIBLE */
 } IndexStmt;
 
 /* ----------------------
diff --git a/src/include/optimizer/optimizer.h b/src/include/optimizer/optimizer.h
index 546828b54bd..3b5ca55bae9 100644
--- a/src/include/optimizer/optimizer.h
+++ b/src/include/optimizer/optimizer.h
@@ -212,4 +212,9 @@ extern List *pull_var_clause(Node *node, int flags);
 extern Node *flatten_join_alias_vars(PlannerInfo *root, Query *query, Node *node);
 extern Node *flatten_group_exprs(PlannerInfo *root, Query *query, Node *node);
 
+/*
+ * GUC to tell planner to consider invisible indexes.
+ */
+extern bool use_invisible_index;
+
 #endif							/* OPTIMIZER_H */
diff --git a/src/include/parser/kwlist.h b/src/include/parser/kwlist.h
index a4af3f717a1..77da5117cb4 100644
--- a/src/include/parser/kwlist.h
+++ b/src/include/parser/kwlist.h
@@ -229,6 +229,7 @@ PG_KEYWORD("integer", INTEGER, COL_NAME_KEYWORD, BARE_LABEL)
 PG_KEYWORD("intersect", INTERSECT, RESERVED_KEYWORD, AS_LABEL)
 PG_KEYWORD("interval", INTERVAL, COL_NAME_KEYWORD, BARE_LABEL)
 PG_KEYWORD("into", INTO, RESERVED_KEYWORD, AS_LABEL)
+PG_KEYWORD("invisible", INVISIBLE, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("invoker", INVOKER, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("is", IS, TYPE_FUNC_NAME_KEYWORD, BARE_LABEL)
 PG_KEYWORD("isnull", ISNULL, TYPE_FUNC_NAME_KEYWORD, AS_LABEL)
@@ -493,6 +494,7 @@ PG_KEYWORD("version", VERSION_P, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("view", VIEW, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("views", VIEWS, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("virtual", VIRTUAL, UNRESERVED_KEYWORD, BARE_LABEL)
+PG_KEYWORD("visible", VISIBLE, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("volatile", VOLATILE, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("when", WHEN, RESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("where", WHERE, RESERVED_KEYWORD, AS_LABEL)
diff --git a/src/include/utils/guc_hooks.h b/src/include/utils/guc_hooks.h
index 799fa7ace68..dd5128fd871 100644
--- a/src/include/utils/guc_hooks.h
+++ b/src/include/utils/guc_hooks.h
@@ -178,5 +178,6 @@ extern bool check_synchronized_standby_slots(char **newval, void **extra,
 extern void assign_synchronized_standby_slots(const char *newval, void *extra);
 extern bool check_idle_replication_slot_timeout(int *newval, void **extra,
 												GucSource source);
+extern void assign_use_invisible_index(bool newval, void *extra);
 
 #endif							/* GUC_HOOKS_H */
diff --git a/src/test/modules/test_ddl_deparse/Makefile b/src/test/modules/test_ddl_deparse/Makefile
index 3a57a95c849..747d8b5835c 100644
--- a/src/test/modules/test_ddl_deparse/Makefile
+++ b/src/test/modules/test_ddl_deparse/Makefile
@@ -27,7 +27,8 @@ REGRESS = test_ddl_deparse \
 	alter_type_enum \
 	opfamily \
 	defprivs \
-	matviews
+	matviews \
+	alter_index
 
 EXTRA_INSTALL = contrib/pg_stat_statements
 
diff --git a/src/test/modules/test_ddl_deparse/expected/alter_index.out b/src/test/modules/test_ddl_deparse/expected/alter_index.out
new file mode 100644
index 00000000000..f502baf1c58
--- /dev/null
+++ b/src/test/modules/test_ddl_deparse/expected/alter_index.out
@@ -0,0 +1,29 @@
+-- Test index visibility commands
+CREATE TABLE visibility_test (id int);
+NOTICE:  DDL test: type simple, tag CREATE TABLE
+CREATE INDEX idx_vis ON visibility_test(id);
+NOTICE:  DDL test: type simple, tag CREATE INDEX
+ALTER INDEX idx_vis INVISIBLE;
+NOTICE:  DDL test: type alter table, tag ALTER INDEX
+NOTICE:    subcommand: type SET INVISIBLE desc <NULL>
+ALTER INDEX idx_vis VISIBLE;
+NOTICE:  DDL test: type alter table, tag ALTER INDEX
+NOTICE:    subcommand: type SET VISIBLE desc <NULL>
+ALTER INDEX idx_vis INVISIBLE;
+NOTICE:  DDL test: type alter table, tag ALTER INDEX
+NOTICE:    subcommand: type SET INVISIBLE desc <NULL>
+REINDEX INDEX idx_vis;
+NOTICE:  DDL test: type simple, tag REINDEX
+CREATE SCHEMA visibility_schema;
+NOTICE:  DDL test: type simple, tag CREATE SCHEMA
+CREATE TABLE visibility_schema.test2 (id int);
+NOTICE:  DDL test: type simple, tag CREATE TABLE
+CREATE INDEX idx_vis2 ON visibility_schema.test2(id);
+NOTICE:  DDL test: type simple, tag CREATE INDEX
+ALTER INDEX visibility_schema.idx_vis2 INVISIBLE;
+NOTICE:  DDL test: type alter table, tag ALTER INDEX
+NOTICE:    subcommand: type SET INVISIBLE desc <NULL>
+-- Clean up
+DROP SCHEMA visibility_schema CASCADE;
+NOTICE:  drop cascades to table visibility_schema.test2
+DROP TABLE visibility_test CASCADE;
diff --git a/src/test/modules/test_ddl_deparse/meson.build b/src/test/modules/test_ddl_deparse/meson.build
index bff65ba6333..6654b5e46df 100644
--- a/src/test/modules/test_ddl_deparse/meson.build
+++ b/src/test/modules/test_ddl_deparse/meson.build
@@ -48,6 +48,7 @@ tests += {
       'opfamily',
       'defprivs',
       'matviews',
+      'alter_index',
     ],
   },
 }
diff --git a/src/test/modules/test_ddl_deparse/sql/alter_index.sql b/src/test/modules/test_ddl_deparse/sql/alter_index.sql
new file mode 100644
index 00000000000..7a34dc6692e
--- /dev/null
+++ b/src/test/modules/test_ddl_deparse/sql/alter_index.sql
@@ -0,0 +1,18 @@
+-- Test index visibility commands
+CREATE TABLE visibility_test (id int);
+CREATE INDEX idx_vis ON visibility_test(id);
+
+ALTER INDEX idx_vis INVISIBLE;
+ALTER INDEX idx_vis VISIBLE;
+
+ALTER INDEX idx_vis INVISIBLE;
+REINDEX INDEX idx_vis;
+
+CREATE SCHEMA visibility_schema;
+CREATE TABLE visibility_schema.test2 (id int);
+CREATE INDEX idx_vis2 ON visibility_schema.test2(id);
+ALTER INDEX visibility_schema.idx_vis2 INVISIBLE;
+
+-- Clean up
+DROP SCHEMA visibility_schema CASCADE;
+DROP TABLE visibility_test CASCADE;
diff --git a/src/test/modules/test_ddl_deparse/test_ddl_deparse.c b/src/test/modules/test_ddl_deparse/test_ddl_deparse.c
index 193669f2bc1..8d7c7e58949 100644
--- a/src/test/modules/test_ddl_deparse/test_ddl_deparse.c
+++ b/src/test/modules/test_ddl_deparse/test_ddl_deparse.c
@@ -308,6 +308,12 @@ get_altertable_subcmdinfo(PG_FUNCTION_ARGS)
 			case AT_ReAddStatistics:
 				strtype = "(re) ADD STATS";
 				break;
+			case AT_SetIndexVisible:
+				strtype = "SET VISIBLE";
+				break;
+			case AT_SetIndexInvisible:
+				strtype = "SET INVISIBLE";
+				break;
 		}
 
 		if (subcmd->recurse)
diff --git a/src/test/regress/expected/create_index.out b/src/test/regress/expected/create_index.out
index 9ade7b835e6..2ba2397a125 100644
--- a/src/test/regress/expected/create_index.out
+++ b/src/test/regress/expected/create_index.out
@@ -3542,6 +3542,801 @@ ERROR:  REINDEX SCHEMA cannot run inside a transaction block
 END;
 -- concurrently
 REINDEX SCHEMA CONCURRENTLY schema_to_reindex;
+-- Test index visibility functionality
+CREATE TABLE index_test(
+    id INT PRIMARY KEY,
+    data TEXT,
+    num INT,
+    vector INT[],
+    range INT4RANGE
+);
+INSERT INTO index_test
+SELECT
+    g,
+    'data ' || g,
+    g % 100,
+    ARRAY[g, g+1, g+2],
+    int4range(g, g+10)
+FROM generate_series(1, 1000) g;
+-- Function for testing
+CREATE FUNCTION get_data_length(text) RETURNS INT AS $$
+    SELECT length($1);
+$$ LANGUAGE SQL IMMUTABLE;
+-- Helper function to show index status
+CREATE OR REPLACE FUNCTION show_index_status(index_name text)
+RETURNS TABLE (
+    indexrelid regclass,
+    indisvalid boolean,
+    indisready boolean,
+    indislive boolean,
+    indisvisible boolean
+) AS $$
+BEGIN
+    RETURN QUERY EXECUTE format('
+        SELECT indexrelid::regclass, indisvalid, indisready, indislive, indisvisible
+        FROM pg_index
+        WHERE indexrelid = %L::regclass', index_name);
+END;
+$$ LANGUAGE plpgsql;
+-- Create and test each index type
+-- 1. Basic single-column index
+CREATE INDEX idx_single ON index_test(data);
+SELECT show_index_status('idx_single');
+  show_index_status   
+----------------------
+ (idx_single,t,t,t,t)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE data = 'data 500';
+                  QUERY PLAN                   
+-----------------------------------------------
+ Bitmap Heap Scan on index_test
+   Recheck Cond: (data = 'data 500'::text)
+   ->  Bitmap Index Scan on idx_single
+         Index Cond: (data = 'data 500'::text)
+(4 rows)
+
+ALTER INDEX idx_single INVISIBLE;
+SELECT show_index_status('idx_single');
+  show_index_status   
+----------------------
+ (idx_single,t,t,t,f)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE data = 'data 500';
+             QUERY PLAN              
+-------------------------------------
+ Seq Scan on index_test
+   Filter: (data = 'data 500'::text)
+(2 rows)
+
+ALTER INDEX idx_single VISIBLE;
+SELECT show_index_status('idx_single');
+  show_index_status   
+----------------------
+ (idx_single,t,t,t,t)
+(1 row)
+
+-- 2. Multi-column index
+CREATE INDEX idx_multi ON index_test(num, data);
+SELECT show_index_status('idx_multi');
+  show_index_status  
+---------------------
+ (idx_multi,t,t,t,t)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE num = 50 AND data > 'data 500';
+                           QUERY PLAN                           
+----------------------------------------------------------------
+ Bitmap Heap Scan on index_test
+   Recheck Cond: ((num = 50) AND (data > 'data 500'::text))
+   ->  Bitmap Index Scan on idx_multi
+         Index Cond: ((num = 50) AND (data > 'data 500'::text))
+(4 rows)
+
+ALTER INDEX idx_multi INVISIBLE;
+SELECT show_index_status('idx_multi');
+  show_index_status  
+---------------------
+ (idx_multi,t,t,t,f)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE num = 50 AND data > 'data 500';
+                      QUERY PLAN                      
+------------------------------------------------------
+ Seq Scan on index_test
+   Filter: ((data > 'data 500'::text) AND (num = 50))
+(2 rows)
+
+ALTER INDEX idx_multi VISIBLE;
+SELECT show_index_status('idx_multi');
+  show_index_status  
+---------------------
+ (idx_multi,t,t,t,t)
+(1 row)
+
+-- 3. Partial index
+CREATE INDEX idx_partial ON index_test(num) WHERE num < 50;
+SELECT show_index_status('idx_partial');
+   show_index_status   
+-----------------------
+ (idx_partial,t,t,t,t)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE num = 25;
+               QUERY PLAN               
+----------------------------------------
+ Bitmap Heap Scan on index_test
+   Recheck Cond: (num = 25)
+   ->  Bitmap Index Scan on idx_partial
+         Index Cond: (num = 25)
+(4 rows)
+
+ALTER INDEX idx_partial INVISIBLE;
+SELECT show_index_status('idx_partial');
+   show_index_status   
+-----------------------
+ (idx_partial,t,t,t,f)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE num = 25;
+              QUERY PLAN              
+--------------------------------------
+ Bitmap Heap Scan on index_test
+   Recheck Cond: (num = 25)
+   ->  Bitmap Index Scan on idx_multi
+         Index Cond: (num = 25)
+(4 rows)
+
+ALTER INDEX idx_partial VISIBLE;
+SELECT show_index_status('idx_partial');
+   show_index_status   
+-----------------------
+ (idx_partial,t,t,t,t)
+(1 row)
+
+-- 4. Expression index
+CREATE INDEX idx_expression ON index_test((lower(data)));
+SELECT show_index_status('idx_expression');
+    show_index_status     
+--------------------------
+ (idx_expression,t,t,t,t)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE lower(data) = 'data 500';
+                      QUERY PLAN                      
+------------------------------------------------------
+ Bitmap Heap Scan on index_test
+   Recheck Cond: (lower(data) = 'data 500'::text)
+   ->  Bitmap Index Scan on idx_expression
+         Index Cond: (lower(data) = 'data 500'::text)
+(4 rows)
+
+ALTER INDEX idx_expression INVISIBLE;
+SELECT show_index_status('idx_expression');
+    show_index_status     
+--------------------------
+ (idx_expression,t,t,t,f)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE lower(data) = 'data 500';
+                 QUERY PLAN                 
+--------------------------------------------
+ Seq Scan on index_test
+   Filter: (lower(data) = 'data 500'::text)
+(2 rows)
+
+ALTER INDEX idx_expression VISIBLE;
+SELECT show_index_status('idx_expression');
+    show_index_status     
+--------------------------
+ (idx_expression,t,t,t,t)
+(1 row)
+
+-- 5. GIN index
+CREATE INDEX idx_gin ON index_test USING gin(vector);
+SELECT show_index_status('idx_gin');
+ show_index_status 
+-------------------
+ (idx_gin,t,t,t,t)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE vector @> ARRAY[500];
+                     QUERY PLAN                     
+----------------------------------------------------
+ Bitmap Heap Scan on index_test
+   Recheck Cond: (vector @> '{500}'::integer[])
+   ->  Bitmap Index Scan on idx_gin
+         Index Cond: (vector @> '{500}'::integer[])
+(4 rows)
+
+ALTER INDEX idx_gin INVISIBLE;
+SELECT show_index_status('idx_gin');
+ show_index_status 
+-------------------
+ (idx_gin,t,t,t,f)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE vector @> ARRAY[500];
+                QUERY PLAN                
+------------------------------------------
+ Seq Scan on index_test
+   Filter: (vector @> '{500}'::integer[])
+(2 rows)
+
+ALTER INDEX idx_gin VISIBLE;
+SELECT show_index_status('idx_gin');
+ show_index_status 
+-------------------
+ (idx_gin,t,t,t,t)
+(1 row)
+
+-- 6. GiST index
+CREATE INDEX idx_gist ON index_test USING gist(range);
+SELECT show_index_status('idx_gist');
+ show_index_status  
+--------------------
+ (idx_gist,t,t,t,t)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE range && int4range(100, 110);
+                      QUERY PLAN                       
+-------------------------------------------------------
+ Bitmap Heap Scan on index_test
+   Recheck Cond: (range && '[100,110)'::int4range)
+   ->  Bitmap Index Scan on idx_gist
+         Index Cond: (range && '[100,110)'::int4range)
+(4 rows)
+
+ALTER INDEX idx_gist INVISIBLE;
+SELECT show_index_status('idx_gist');
+ show_index_status  
+--------------------
+ (idx_gist,t,t,t,f)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE range && int4range(100, 110);
+                 QUERY PLAN                  
+---------------------------------------------
+ Seq Scan on index_test
+   Filter: (range && '[100,110)'::int4range)
+(2 rows)
+
+ALTER INDEX idx_gist VISIBLE;
+SELECT show_index_status('idx_gist');
+ show_index_status  
+--------------------
+ (idx_gist,t,t,t,t)
+(1 row)
+
+-- 7. Covering index
+CREATE INDEX idx_covering ON index_test(num) INCLUDE (data);
+SELECT show_index_status('idx_covering');
+   show_index_status    
+------------------------
+ (idx_covering,t,t,t,t)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT num, data FROM index_test WHERE num = 50;
+               QUERY PLAN                
+-----------------------------------------
+ Bitmap Heap Scan on index_test
+   Recheck Cond: (num = 50)
+   ->  Bitmap Index Scan on idx_covering
+         Index Cond: (num = 50)
+(4 rows)
+
+ALTER INDEX idx_covering INVISIBLE;
+SELECT show_index_status('idx_covering');
+   show_index_status    
+------------------------
+ (idx_covering,t,t,t,f)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT num, data FROM index_test WHERE num = 50;
+              QUERY PLAN              
+--------------------------------------
+ Bitmap Heap Scan on index_test
+   Recheck Cond: (num = 50)
+   ->  Bitmap Index Scan on idx_multi
+         Index Cond: (num = 50)
+(4 rows)
+
+ALTER INDEX idx_covering VISIBLE;
+SELECT show_index_status('idx_covering');
+   show_index_status    
+------------------------
+ (idx_covering,t,t,t,t)
+(1 row)
+
+-- 8. Unique index
+CREATE UNIQUE INDEX idx_unique ON index_test(id, data);
+SELECT show_index_status('idx_unique');
+  show_index_status   
+----------------------
+ (idx_unique,t,t,t,t)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE id = 500 AND data = 'data 500';
+                        QUERY PLAN                        
+----------------------------------------------------------
+ Index Scan using idx_unique on index_test
+   Index Cond: ((id = 500) AND (data = 'data 500'::text))
+(2 rows)
+
+ALTER INDEX idx_unique INVISIBLE;
+SELECT show_index_status('idx_unique');
+  show_index_status   
+----------------------
+ (idx_unique,t,t,t,f)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE id = 500 AND data = 'data 500';
+                   QUERY PLAN                   
+------------------------------------------------
+ Index Scan using index_test_pkey on index_test
+   Index Cond: (id = 500)
+   Filter: (data = 'data 500'::text)
+(3 rows)
+
+ALTER INDEX idx_unique VISIBLE;
+SELECT show_index_status('idx_unique');
+  show_index_status   
+----------------------
+ (idx_unique,t,t,t,t)
+(1 row)
+
+-- 9. Function-based index
+CREATE INDEX idx_func ON index_test(get_data_length(data));
+SELECT show_index_status('idx_func');
+ show_index_status  
+--------------------
+ (idx_func,t,t,t,t)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE get_data_length(data) = 10;
+               QUERY PLAN                
+-----------------------------------------
+ Bitmap Heap Scan on index_test
+   Recheck Cond: (length(data) = 10)
+   ->  Bitmap Index Scan on idx_func
+         Index Cond: (length(data) = 10)
+(4 rows)
+
+ALTER INDEX idx_func INVISIBLE;
+SELECT show_index_status('idx_func');
+ show_index_status  
+--------------------
+ (idx_func,t,t,t,f)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE get_data_length(data) = 10;
+          QUERY PLAN           
+-------------------------------
+ Seq Scan on index_test
+   Filter: (length(data) = 10)
+(2 rows)
+
+ALTER INDEX idx_func VISIBLE;
+SELECT show_index_status('idx_func');
+ show_index_status  
+--------------------
+ (idx_func,t,t,t,t)
+(1 row)
+
+-- 10. Join index
+CREATE TABLE join_test (id INT PRIMARY KEY, ref_id INT);
+INSERT INTO join_test SELECT g, g % 100 FROM generate_series(1, 1000) g;
+CREATE INDEX idx_join ON join_test(ref_id);
+SELECT show_index_status('idx_join');
+ show_index_status  
+--------------------
+ (idx_join,t,t,t,t)
+(1 row)
+
+EXPLAIN (COSTS OFF)
+SELECT jt.id, it.data
+FROM join_test jt
+JOIN index_test it ON jt.ref_id = it.num
+WHERE jt.id BETWEEN 100 AND 200;
+                          QUERY PLAN                           
+---------------------------------------------------------------
+ Hash Join
+   Hash Cond: (it.num = jt.ref_id)
+   ->  Seq Scan on index_test it
+   ->  Hash
+         ->  Bitmap Heap Scan on join_test jt
+               Recheck Cond: ((id >= 100) AND (id <= 200))
+               ->  Bitmap Index Scan on join_test_pkey
+                     Index Cond: ((id >= 100) AND (id <= 200))
+(8 rows)
+
+-- Set all indexes to invisible to force seq scan
+ALTER INDEX idx_join INVISIBLE;
+ALTER INDEX join_test_pkey INVISIBLE;
+SELECT show_index_status('idx_join');
+ show_index_status  
+--------------------
+ (idx_join,t,t,t,f)
+(1 row)
+
+SELECT show_index_status('join_test_pkey');
+    show_index_status     
+--------------------------
+ (join_test_pkey,t,t,t,f)
+(1 row)
+
+EXPLAIN (COSTS OFF)
+SELECT jt.id, it.data
+FROM join_test jt
+JOIN index_test it ON jt.ref_id = it.num
+WHERE jt.id BETWEEN 100 AND 200;
+                     QUERY PLAN                      
+-----------------------------------------------------
+ Hash Join
+   Hash Cond: (it.num = jt.ref_id)
+   ->  Seq Scan on index_test it
+   ->  Hash
+         ->  Seq Scan on join_test jt
+               Filter: ((id >= 100) AND (id <= 200))
+(6 rows)
+
+ALTER INDEX idx_join VISIBLE;
+ALTER INDEX join_test_pkey VISIBLE;
+SELECT show_index_status('idx_join');
+ show_index_status  
+--------------------
+ (idx_join,t,t,t,t)
+(1 row)
+
+SELECT show_index_status('join_test_pkey');
+    show_index_status     
+--------------------------
+ (join_test_pkey,t,t,t,t)
+(1 row)
+
+-- Test REINDEX CONCURRENTLY
+REINDEX INDEX CONCURRENTLY idx_join;
+SELECT show_index_status('idx_join');
+ show_index_status  
+--------------------
+ (idx_join,t,t,t,t)
+(1 row)
+
+ALTER INDEX idx_join INVISIBLE;
+SELECT show_index_status('idx_join');
+ show_index_status  
+--------------------
+ (idx_join,t,t,t,f)
+(1 row)
+
+REINDEX INDEX CONCURRENTLY idx_join;
+SELECT show_index_status('idx_join');
+ show_index_status  
+--------------------
+ (idx_join,t,t,t,f)
+(1 row)
+
+SELECT pg_get_indexdef('idx_join'::regclass);
+                                   pg_get_indexdef                                   
+-------------------------------------------------------------------------------------
+ CREATE INDEX idx_join ON schema_to_reindex.join_test USING btree (ref_id) INVISIBLE
+(1 row)
+
+ALTER INDEX idx_join VISIBLE;
+SELECT pg_get_indexdef('idx_join'::regclass);
+                              pg_get_indexdef                              
+---------------------------------------------------------------------------
+ CREATE INDEX idx_join ON schema_to_reindex.join_test USING btree (ref_id)
+(1 row)
+
+-- Test index visibility with indcheckxmin being true
+CREATE TABLE indcheckxmin_test(id int PRIMARY KEY);
+INSERT INTO indcheckxmin_test VALUES (1), (2), (3);
+CREATE INDEX CONCURRENTLY idx_checkxmin ON indcheckxmin_test(id);
+BEGIN;
+-- Simulate indcheckxmin being true
+UPDATE pg_index SET indcheckxmin = true WHERE indexrelid = 'idx_checkxmin'::regclass;
+ALTER INDEX idx_checkxmin INVISIBLE;  -- expect fail
+ERROR:  cannot update index visibility while indcheckxmin is true
+HINT:  Wait for all transactions that might see inconsistent HOT chains to complete
+ROLLBACK;
+-- Test prepared statements with index visibility
+CREATE TABLE prep_idx_test (id int, data text);
+CREATE INDEX prep_idx1 ON prep_idx_test(data);
+INSERT INTO prep_idx_test SELECT g, 'data ' || g FROM generate_series(1,100) g;
+-- Test with visible index
+PREPARE idx_plan AS SELECT * FROM prep_idx_test WHERE data = $1;
+EXPLAIN (COSTS OFF) EXECUTE idx_plan('data 1');
+                 QUERY PLAN                  
+---------------------------------------------
+ Bitmap Heap Scan on prep_idx_test
+   Recheck Cond: (data = 'data 1'::text)
+   ->  Bitmap Index Scan on prep_idx1
+         Index Cond: (data = 'data 1'::text)
+(4 rows)
+
+EXECUTE idx_plan('data 1');
+ id |  data  
+----+--------
+  1 | data 1
+(1 row)
+
+-- Test with invisible index
+ALTER INDEX prep_idx1 INVISIBLE;
+EXPLAIN (COSTS OFF) EXECUTE idx_plan('data 1');
+            QUERY PLAN             
+-----------------------------------
+ Seq Scan on prep_idx_test
+   Filter: (data = 'data 1'::text)
+(2 rows)
+
+EXECUTE idx_plan('data 1');
+ id |  data  
+----+--------
+  1 | data 1
+(1 row)
+
+-- Test with use_invisible_index
+SET use_invisible_index TO on;
+EXPLAIN (COSTS OFF) EXECUTE idx_plan('data 1');
+                 QUERY PLAN                  
+---------------------------------------------
+ Bitmap Heap Scan on prep_idx_test
+   Recheck Cond: (data = 'data 1'::text)
+   ->  Bitmap Index Scan on prep_idx1
+         Index Cond: (data = 'data 1'::text)
+(4 rows)
+
+EXECUTE idx_plan('data 1');
+ id |  data  
+----+--------
+  1 | data 1
+(1 row)
+
+SET use_invisible_index TO off;
+-- Assert plan cache is reset and index is not used
+EXPLAIN (COSTS OFF) EXECUTE idx_plan('data 1');
+            QUERY PLAN             
+-----------------------------------
+ Seq Scan on prep_idx_test
+   Filter: (data = 'data 1'::text)
+(2 rows)
+
+-- Make index visible and test again
+ALTER INDEX prep_idx1 VISIBLE;
+EXPLAIN (COSTS OFF) EXECUTE idx_plan('data 1');
+                 QUERY PLAN                  
+---------------------------------------------
+ Bitmap Heap Scan on prep_idx_test
+   Recheck Cond: (data = 'data 1'::text)
+   ->  Bitmap Index Scan on prep_idx1
+         Index Cond: (data = 'data 1'::text)
+(4 rows)
+
+EXECUTE idx_plan('data 1');
+ id |  data  
+----+--------
+  1 | data 1
+(1 row)
+
+-- Test index visibility with partitioned tables
+CREATE TABLE part_tbl(id int, data text) PARTITION BY RANGE(id);
+CREATE TABLE part1 PARTITION OF part_tbl FOR VALUES FROM (1) TO (100);
+CREATE TABLE part2 PARTITION OF part_tbl FOR VALUES FROM (100) TO (200);
+INSERT INTO part_tbl
+SELECT g, 'data ' || g
+FROM generate_series(1, 199) g;
+CREATE INDEX idx_part_tbl ON part_tbl(data);
+SELECT c.relname, i.indisvisible
+FROM pg_index i
+JOIN pg_class c ON i.indexrelid = c.oid
+WHERE c.relname LIKE 'idx_part_tbl%'
+ORDER BY c.relname;
+   relname    | indisvisible 
+--------------+--------------
+ idx_part_tbl | t
+(1 row)
+
+-- Force use of indexes to avoid flaky test results
+SET enable_seqscan = off;
+EXPLAIN (COSTS OFF)
+SELECT * FROM part_tbl WHERE data = 'data 50';
+                        QUERY PLAN                         
+-----------------------------------------------------------
+ Append
+   ->  Index Scan using part1_data_idx on part1 part_tbl_1
+         Index Cond: (data = 'data 50'::text)
+   ->  Index Scan using part2_data_idx on part2 part_tbl_2
+         Index Cond: (data = 'data 50'::text)
+(5 rows)
+
+ALTER INDEX idx_part_tbl INVISIBLE;
+SELECT c.relname, i.indisvisible
+FROM pg_index i
+JOIN pg_class c ON i.indexrelid = c.oid
+WHERE c.relname LIKE 'idx_part_tbl%'
+ORDER BY c.relname;
+   relname    | indisvisible 
+--------------+--------------
+ idx_part_tbl | f
+(1 row)
+
+-- Check query plan after setting invisible (should use seq scan)
+EXPLAIN (COSTS OFF)
+SELECT * FROM part_tbl WHERE data = 'data 50';
+                QUERY PLAN                
+------------------------------------------
+ Append
+   ->  Seq Scan on part1 part_tbl_1
+         Disabled: true
+         Filter: (data = 'data 50'::text)
+   ->  Seq Scan on part2 part_tbl_2
+         Disabled: true
+         Filter: (data = 'data 50'::text)
+(7 rows)
+
+SET use_invisible_index TO on;
+EXPLAIN (COSTS OFF)
+SELECT * FROM part_tbl WHERE data = 'data 50';
+                        QUERY PLAN                         
+-----------------------------------------------------------
+ Append
+   ->  Index Scan using part1_data_idx on part1 part_tbl_1
+         Index Cond: (data = 'data 50'::text)
+   ->  Index Scan using part2_data_idx on part2 part_tbl_2
+         Index Cond: (data = 'data 50'::text)
+(5 rows)
+
+SET use_invisible_index TO off;
+EXPLAIN (COSTS OFF)
+SELECT * FROM part_tbl WHERE data = 'data 50';
+                QUERY PLAN                
+------------------------------------------
+ Append
+   ->  Seq Scan on part1 part_tbl_1
+         Disabled: true
+         Filter: (data = 'data 50'::text)
+   ->  Seq Scan on part2 part_tbl_2
+         Disabled: true
+         Filter: (data = 'data 50'::text)
+(7 rows)
+
+ALTER INDEX idx_part_tbl VISIBLE;
+SELECT c.relname, i.indisvisible
+FROM pg_index i
+JOIN pg_class c ON i.indexrelid = c.oid
+WHERE c.relname LIKE 'idx_part_tbl%'
+ORDER BY c.relname;
+   relname    | indisvisible 
+--------------+--------------
+ idx_part_tbl | t
+(1 row)
+
+EXPLAIN (COSTS OFF)
+SELECT * FROM part_tbl WHERE data = 'data 50';
+                        QUERY PLAN                         
+-----------------------------------------------------------
+ Append
+   ->  Index Scan using part1_data_idx on part1 part_tbl_1
+         Index Cond: (data = 'data 50'::text)
+   ->  Index Scan using part2_data_idx on part2 part_tbl_2
+         Index Cond: (data = 'data 50'::text)
+(5 rows)
+
+SET enable_seqscan = on;
+-- Test REINDEX maintains visibility setting
+ALTER INDEX idx_part_tbl INVISIBLE;
+REINDEX INDEX idx_part_tbl;
+SELECT c.relname, i.indisvisible
+FROM pg_index i
+JOIN pg_class c ON i.indexrelid = c.oid
+WHERE c.relname LIKE 'idx_part_tbl%'
+ORDER BY c.relname;
+   relname    | indisvisible 
+--------------+--------------
+ idx_part_tbl | f
+(1 row)
+
+-- Test that index visibility is preserved after ALTER TABLE
+CREATE TABLE vis_test(id INT PRIMARY KEY, data text);
+\d vis_test
+        Table "schema_to_reindex.vis_test"
+ Column |  Type   | Collation | Nullable | Default 
+--------+---------+-----------+----------+---------
+ id     | integer |           | not null | 
+ data   | text    |           |          | 
+Indexes:
+    "vis_test_pkey" PRIMARY KEY, btree (id)
+
+ALTER INDEX vis_test_pkey INVISIBLE;
+\d vis_test
+        Table "schema_to_reindex.vis_test"
+ Column |  Type   | Collation | Nullable | Default 
+--------+---------+-----------+----------+---------
+ id     | integer |           | not null | 
+ data   | text    |           |          | 
+Indexes:
+    "vis_test_pkey" PRIMARY KEY, btree (id) INVISIBLE
+
+ALTER TABLE vis_test ALTER COLUMN id SET DATA TYPE bigint;
+\d vis_test
+        Table "schema_to_reindex.vis_test"
+ Column |  Type  | Collation | Nullable | Default 
+--------+--------+-----------+----------+---------
+ id     | bigint |           | not null | 
+ data   | text   |           |          | 
+Indexes:
+    "vis_test_pkey" PRIMARY KEY, btree (id) INVISIBLE
+
+ALTER TABLE vis_test ALTER COLUMN id SET DATA TYPE int;
+\d vis_test
+        Table "schema_to_reindex.vis_test"
+ Column |  Type   | Collation | Nullable | Default 
+--------+---------+-----------+----------+---------
+ id     | integer |           | not null | 
+ data   | text    |           |          | 
+Indexes:
+    "vis_test_pkey" PRIMARY KEY, btree (id) INVISIBLE
+
+ALTER INDEX vis_test_pkey VISIBLE;
+\d vis_test
+        Table "schema_to_reindex.vis_test"
+ Column |  Type   | Collation | Nullable | Default 
+--------+---------+-----------+----------+---------
+ id     | integer |           | not null | 
+ data   | text    |           |          | 
+Indexes:
+    "vis_test_pkey" PRIMARY KEY, btree (id)
+
+-- Test CREATE INDEX with INVISIBLE option
+CREATE TABLE invis_test(id int, data text);
+INSERT INTO invis_test SELECT g, 'data ' || g FROM generate_series(1,100) g;
+CREATE INDEX idx_invis1 ON invis_test(data) INVISIBLE;
+\d invis_test
+       Table "schema_to_reindex.invis_test"
+ Column |  Type   | Collation | Nullable | Default 
+--------+---------+-----------+----------+---------
+ id     | integer |           |          | 
+ data   | text    |           |          | 
+Indexes:
+    "idx_invis1" btree (data) INVISIBLE
+
+\d idx_invis1
+Index "schema_to_reindex.idx_invis1"
+ Column | Type | Key? | Definition 
+--------+------+------+------------
+ data   | text | yes  | data
+btree, for table "schema_to_reindex.invis_test", invisible
+
+ALTER INDEX idx_invis1 VISIBLE;
+\d invis_test
+       Table "schema_to_reindex.invis_test"
+ Column |  Type   | Collation | Nullable | Default 
+--------+---------+-----------+----------+---------
+ id     | integer |           |          | 
+ data   | text    |           |          | 
+Indexes:
+    "idx_invis1" btree (data)
+
+\d idx_invis1
+Index "schema_to_reindex.idx_invis1"
+ Column | Type | Key? | Definition 
+--------+------+------+------------
+ data   | text | yes  | data
+btree, for table "schema_to_reindex.invis_test"
+
+-- Clean up
+DROP TABLE index_test;
+DROP TABLE join_test;
+DROP FUNCTION get_data_length;
+DROP FUNCTION show_index_status;
+DROP TABLE indcheckxmin_test CASCADE;
+DEALLOCATE idx_plan;
+DROP TABLE prep_idx_test;
+DROP TABLE part_tbl CASCADE;
+DROP TABLE vis_test;
+DROP TABLE invis_test;
 -- Failure for unauthorized user
 CREATE ROLE regress_reindexuser NOLOGIN;
 SET SESSION ROLE regress_reindexuser;
diff --git a/src/test/regress/sql/create_index.sql b/src/test/regress/sql/create_index.sql
index e21ff426519..b4bea3f9d94 100644
--- a/src/test/regress/sql/create_index.sql
+++ b/src/test/regress/sql/create_index.sql
@@ -1496,6 +1496,327 @@ END;
 -- concurrently
 REINDEX SCHEMA CONCURRENTLY schema_to_reindex;
 
+-- Test index visibility functionality
+
+CREATE TABLE index_test(
+    id INT PRIMARY KEY,
+    data TEXT,
+    num INT,
+    vector INT[],
+    range INT4RANGE
+);
+
+INSERT INTO index_test
+SELECT
+    g,
+    'data ' || g,
+    g % 100,
+    ARRAY[g, g+1, g+2],
+    int4range(g, g+10)
+FROM generate_series(1, 1000) g;
+
+-- Function for testing
+CREATE FUNCTION get_data_length(text) RETURNS INT AS $$
+    SELECT length($1);
+$$ LANGUAGE SQL IMMUTABLE;
+
+-- Helper function to show index status
+CREATE OR REPLACE FUNCTION show_index_status(index_name text)
+RETURNS TABLE (
+    indexrelid regclass,
+    indisvalid boolean,
+    indisready boolean,
+    indislive boolean,
+    indisvisible boolean
+) AS $$
+BEGIN
+    RETURN QUERY EXECUTE format('
+        SELECT indexrelid::regclass, indisvalid, indisready, indislive, indisvisible
+        FROM pg_index
+        WHERE indexrelid = %L::regclass', index_name);
+END;
+$$ LANGUAGE plpgsql;
+
+-- Create and test each index type
+-- 1. Basic single-column index
+CREATE INDEX idx_single ON index_test(data);
+SELECT show_index_status('idx_single');
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE data = 'data 500';
+ALTER INDEX idx_single INVISIBLE;
+SELECT show_index_status('idx_single');
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE data = 'data 500';
+ALTER INDEX idx_single VISIBLE;
+SELECT show_index_status('idx_single');
+
+-- 2. Multi-column index
+CREATE INDEX idx_multi ON index_test(num, data);
+SELECT show_index_status('idx_multi');
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE num = 50 AND data > 'data 500';
+ALTER INDEX idx_multi INVISIBLE;
+SELECT show_index_status('idx_multi');
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE num = 50 AND data > 'data 500';
+ALTER INDEX idx_multi VISIBLE;
+SELECT show_index_status('idx_multi');
+
+-- 3. Partial index
+CREATE INDEX idx_partial ON index_test(num) WHERE num < 50;
+SELECT show_index_status('idx_partial');
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE num = 25;
+ALTER INDEX idx_partial INVISIBLE;
+SELECT show_index_status('idx_partial');
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE num = 25;
+ALTER INDEX idx_partial VISIBLE;
+SELECT show_index_status('idx_partial');
+
+-- 4. Expression index
+CREATE INDEX idx_expression ON index_test((lower(data)));
+SELECT show_index_status('idx_expression');
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE lower(data) = 'data 500';
+ALTER INDEX idx_expression INVISIBLE;
+SELECT show_index_status('idx_expression');
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE lower(data) = 'data 500';
+ALTER INDEX idx_expression VISIBLE;
+SELECT show_index_status('idx_expression');
+
+-- 5. GIN index
+CREATE INDEX idx_gin ON index_test USING gin(vector);
+SELECT show_index_status('idx_gin');
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE vector @> ARRAY[500];
+ALTER INDEX idx_gin INVISIBLE;
+SELECT show_index_status('idx_gin');
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE vector @> ARRAY[500];
+ALTER INDEX idx_gin VISIBLE;
+SELECT show_index_status('idx_gin');
+
+-- 6. GiST index
+CREATE INDEX idx_gist ON index_test USING gist(range);
+SELECT show_index_status('idx_gist');
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE range && int4range(100, 110);
+ALTER INDEX idx_gist INVISIBLE;
+SELECT show_index_status('idx_gist');
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE range && int4range(100, 110);
+ALTER INDEX idx_gist VISIBLE;
+SELECT show_index_status('idx_gist');
+
+-- 7. Covering index
+CREATE INDEX idx_covering ON index_test(num) INCLUDE (data);
+SELECT show_index_status('idx_covering');
+EXPLAIN (COSTS OFF) SELECT num, data FROM index_test WHERE num = 50;
+ALTER INDEX idx_covering INVISIBLE;
+SELECT show_index_status('idx_covering');
+EXPLAIN (COSTS OFF) SELECT num, data FROM index_test WHERE num = 50;
+ALTER INDEX idx_covering VISIBLE;
+SELECT show_index_status('idx_covering');
+
+-- 8. Unique index
+CREATE UNIQUE INDEX idx_unique ON index_test(id, data);
+SELECT show_index_status('idx_unique');
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE id = 500 AND data = 'data 500';
+ALTER INDEX idx_unique INVISIBLE;
+SELECT show_index_status('idx_unique');
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE id = 500 AND data = 'data 500';
+ALTER INDEX idx_unique VISIBLE;
+SELECT show_index_status('idx_unique');
+
+-- 9. Function-based index
+CREATE INDEX idx_func ON index_test(get_data_length(data));
+SELECT show_index_status('idx_func');
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE get_data_length(data) = 10;
+ALTER INDEX idx_func INVISIBLE;
+SELECT show_index_status('idx_func');
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE get_data_length(data) = 10;
+ALTER INDEX idx_func VISIBLE;
+SELECT show_index_status('idx_func');
+
+-- 10. Join index
+CREATE TABLE join_test (id INT PRIMARY KEY, ref_id INT);
+INSERT INTO join_test SELECT g, g % 100 FROM generate_series(1, 1000) g;
+CREATE INDEX idx_join ON join_test(ref_id);
+SELECT show_index_status('idx_join');
+
+EXPLAIN (COSTS OFF)
+SELECT jt.id, it.data
+FROM join_test jt
+JOIN index_test it ON jt.ref_id = it.num
+WHERE jt.id BETWEEN 100 AND 200;
+
+-- Set all indexes to invisible to force seq scan
+ALTER INDEX idx_join INVISIBLE;
+ALTER INDEX join_test_pkey INVISIBLE;
+SELECT show_index_status('idx_join');
+SELECT show_index_status('join_test_pkey');
+
+EXPLAIN (COSTS OFF)
+SELECT jt.id, it.data
+FROM join_test jt
+JOIN index_test it ON jt.ref_id = it.num
+WHERE jt.id BETWEEN 100 AND 200;
+
+ALTER INDEX idx_join VISIBLE;
+ALTER INDEX join_test_pkey VISIBLE;
+SELECT show_index_status('idx_join');
+SELECT show_index_status('join_test_pkey');
+
+-- Test REINDEX CONCURRENTLY
+REINDEX INDEX CONCURRENTLY idx_join;
+SELECT show_index_status('idx_join');
+
+ALTER INDEX idx_join INVISIBLE;
+SELECT show_index_status('idx_join');
+REINDEX INDEX CONCURRENTLY idx_join;
+SELECT show_index_status('idx_join');
+
+SELECT pg_get_indexdef('idx_join'::regclass);
+ALTER INDEX idx_join VISIBLE;
+SELECT pg_get_indexdef('idx_join'::regclass);
+
+-- Test index visibility with indcheckxmin being true
+
+CREATE TABLE indcheckxmin_test(id int PRIMARY KEY);
+INSERT INTO indcheckxmin_test VALUES (1), (2), (3);
+CREATE INDEX CONCURRENTLY idx_checkxmin ON indcheckxmin_test(id);
+BEGIN;
+-- Simulate indcheckxmin being true
+UPDATE pg_index SET indcheckxmin = true WHERE indexrelid = 'idx_checkxmin'::regclass;
+ALTER INDEX idx_checkxmin INVISIBLE;  -- expect fail
+ROLLBACK;
+
+-- Test prepared statements with index visibility
+CREATE TABLE prep_idx_test (id int, data text);
+CREATE INDEX prep_idx1 ON prep_idx_test(data);
+INSERT INTO prep_idx_test SELECT g, 'data ' || g FROM generate_series(1,100) g;
+
+-- Test with visible index
+PREPARE idx_plan AS SELECT * FROM prep_idx_test WHERE data = $1;
+EXPLAIN (COSTS OFF) EXECUTE idx_plan('data 1');
+EXECUTE idx_plan('data 1');
+
+-- Test with invisible index
+ALTER INDEX prep_idx1 INVISIBLE;
+EXPLAIN (COSTS OFF) EXECUTE idx_plan('data 1');
+EXECUTE idx_plan('data 1');
+
+-- Test with use_invisible_index
+SET use_invisible_index TO on;
+EXPLAIN (COSTS OFF) EXECUTE idx_plan('data 1');
+EXECUTE idx_plan('data 1');
+SET use_invisible_index TO off;
+-- Assert plan cache is reset and index is not used
+EXPLAIN (COSTS OFF) EXECUTE idx_plan('data 1');
+
+-- Make index visible and test again
+ALTER INDEX prep_idx1 VISIBLE;
+EXPLAIN (COSTS OFF) EXECUTE idx_plan('data 1');
+EXECUTE idx_plan('data 1');
+
+-- Test index visibility with partitioned tables
+CREATE TABLE part_tbl(id int, data text) PARTITION BY RANGE(id);
+CREATE TABLE part1 PARTITION OF part_tbl FOR VALUES FROM (1) TO (100);
+CREATE TABLE part2 PARTITION OF part_tbl FOR VALUES FROM (100) TO (200);
+
+INSERT INTO part_tbl
+SELECT g, 'data ' || g
+FROM generate_series(1, 199) g;
+
+CREATE INDEX idx_part_tbl ON part_tbl(data);
+
+SELECT c.relname, i.indisvisible
+FROM pg_index i
+JOIN pg_class c ON i.indexrelid = c.oid
+WHERE c.relname LIKE 'idx_part_tbl%'
+ORDER BY c.relname;
+
+-- Force use of indexes to avoid flaky test results
+SET enable_seqscan = off;
+
+EXPLAIN (COSTS OFF)
+SELECT * FROM part_tbl WHERE data = 'data 50';
+
+ALTER INDEX idx_part_tbl INVISIBLE;
+
+SELECT c.relname, i.indisvisible
+FROM pg_index i
+JOIN pg_class c ON i.indexrelid = c.oid
+WHERE c.relname LIKE 'idx_part_tbl%'
+ORDER BY c.relname;
+
+-- Check query plan after setting invisible (should use seq scan)
+EXPLAIN (COSTS OFF)
+SELECT * FROM part_tbl WHERE data = 'data 50';
+
+SET use_invisible_index TO on;
+
+EXPLAIN (COSTS OFF)
+SELECT * FROM part_tbl WHERE data = 'data 50';
+
+SET use_invisible_index TO off;
+
+EXPLAIN (COSTS OFF)
+SELECT * FROM part_tbl WHERE data = 'data 50';
+
+ALTER INDEX idx_part_tbl VISIBLE;
+
+SELECT c.relname, i.indisvisible
+FROM pg_index i
+JOIN pg_class c ON i.indexrelid = c.oid
+WHERE c.relname LIKE 'idx_part_tbl%'
+ORDER BY c.relname;
+
+EXPLAIN (COSTS OFF)
+SELECT * FROM part_tbl WHERE data = 'data 50';
+
+SET enable_seqscan = on;
+
+-- Test REINDEX maintains visibility setting
+ALTER INDEX idx_part_tbl INVISIBLE;
+REINDEX INDEX idx_part_tbl;
+
+SELECT c.relname, i.indisvisible
+FROM pg_index i
+JOIN pg_class c ON i.indexrelid = c.oid
+WHERE c.relname LIKE 'idx_part_tbl%'
+ORDER BY c.relname;
+
+-- Test that index visibility is preserved after ALTER TABLE
+CREATE TABLE vis_test(id INT PRIMARY KEY, data text);
+\d vis_test
+
+ALTER INDEX vis_test_pkey INVISIBLE;
+\d vis_test
+
+ALTER TABLE vis_test ALTER COLUMN id SET DATA TYPE bigint;
+\d vis_test
+
+ALTER TABLE vis_test ALTER COLUMN id SET DATA TYPE int;
+\d vis_test
+
+ALTER INDEX vis_test_pkey VISIBLE;
+\d vis_test
+
+-- Test CREATE INDEX with INVISIBLE option
+CREATE TABLE invis_test(id int, data text);
+INSERT INTO invis_test SELECT g, 'data ' || g FROM generate_series(1,100) g;
+
+CREATE INDEX idx_invis1 ON invis_test(data) INVISIBLE;
+\d invis_test
+\d idx_invis1
+
+ALTER INDEX idx_invis1 VISIBLE;
+\d invis_test
+\d idx_invis1
+
+-- Clean up
+DROP TABLE index_test;
+DROP TABLE join_test;
+DROP FUNCTION get_data_length;
+DROP FUNCTION show_index_status;
+DROP TABLE indcheckxmin_test CASCADE;
+DEALLOCATE idx_plan;
+DROP TABLE prep_idx_test;
+DROP TABLE part_tbl CASCADE;
+DROP TABLE vis_test;
+DROP TABLE invis_test;
+
 -- Failure for unauthorized user
 CREATE ROLE regress_reindexuser NOLOGIN;
 SET SESSION ROLE regress_reindexuser;
-- 
2.39.5 (Apple Git-154)

#86Shayon Mukherjee
shayonj@gmail.com
In reply to: Sami Imseih (#85)
Re: [PATCH] Re: Proposal to Enable/Disable Index using ALTER INDEX

On Mon, Apr 7, 2025 at 5:39 PM Sami Imseih <samimseih@gmail.com> wrote:

Attached v16 with feedback and rebased.

Thanks, and I realized the original tab-complete I proposed
was not entirely correct. I fixed it and also shortened the
commit message.

I was wondering about if the check needed to be more encompassing. Your
proposal definitely makes sense, thank you!

+ else if (TailMatches("INDEX|CONCURRENTLY", "ON", MatchAny, "USING",
MatchAny, "(*)")

Shayon

#87jian he
jian.universality@gmail.com
In reply to: Shayon Mukherjee (#86)
Re: [PATCH] Re: Proposal to Enable/Disable Index using ALTER INDEX

hi.
The following is a review of version 17.

ATExecSetIndexVisibility
if (indexForm->indisvisible != visible)
{
indexForm->indisvisible = visible;
CatalogTupleUpdate(pg_index, &indexTuple->t_self, indexTuple);
CacheInvalidateRelcache(heapRel);
InvokeObjectPostAlterHook(IndexRelationId, indexOid, 0);
CommandCounterIncrement();
}
I am slightly confused. if we already used
CommandCounterIncrement();
then we don't need CacheInvalidateRelcache?

doc/src/sgml/ref/alter_index.sgml
<para>
<command>ALTER INDEX</command> changes the definition of an existing index.
There are several subforms described below. Note that the lock level required
may differ for each subform. An <literal>ACCESS EXCLUSIVE</literal>
lock is held
unless explicitly noted. When multiple subcommands are listed, the lock
held will be the strictest one required from any subcommand.

per the above para, we need mention that ALTER INDEX SET INVISIBLE|INVISIBLE
only use ShareUpdateExclusiveLock?

index_create is called in several places,
most of the time, we use INDEX_CREATE_VISIBLE.
if we define it as INDEX_CREATE_INVISIBLE rather than INDEX_CREATE_VISIBLE
then argument flags required code changes would be less, (i didn't try
it myself)

Similar to get_index_isclustered,
We can place GetIndexVisibility in
src/backend/utils/cache/lsyscache.c,
make it an extern function, so others can use it;
to align with other function names,
maybe rename it as get_index_visibility.

create index v2_idx on v1(data) visible;
is allowed,
doc/src/sgml/ref/create_index.sgml
<synopsis> section need to change to
[ VISIBLE | INVISIBLE ]

?

#88jian he
jian.universality@gmail.com
In reply to: jian he (#87)
Re: [PATCH] Re: Proposal to Enable/Disable Index using ALTER INDEX

hi, two more minor issues.

src/bin/pg_dump/pg_dump.c
if (fout->remoteVersion >= 180000)
need change to
if (fout->remoteVersion >= 190000)

+-- Test index visibility with partitioned tables
+CREATE TABLE part_tbl(id int, data text) PARTITION BY RANGE(id);
+CREATE TABLE part1 PARTITION OF part_tbl FOR VALUES FROM (1) TO (100);
+CREATE TABLE part2 PARTITION OF part_tbl FOR VALUES FROM (100) TO (200);
+INSERT INTO part_tbl
+SELECT g, 'data ' || g
+FROM generate_series(1, 199) g;
+CREATE INDEX idx_part_tbl ON part_tbl(data);
+SELECT c.relname, i.indisvisible
+FROM pg_index i
+JOIN pg_class c ON i.indexrelid = c.oid
+WHERE c.relname LIKE 'idx_part_tbl%'
+ORDER BY c.relname;
+   relname    | indisvisible
+--------------+--------------
+ idx_part_tbl | t
+(1 row)
+

This test seems not that good?
"idx_part_tbl" is the partitioned index, we also need to show each
partition index
pg_index.indisvisible value?

we can change it to
--------
CREATE TABLE part_tbl(id int, data text) PARTITION BY RANGE(id);
CREATE TABLE part_tbl_1 PARTITION OF part_tbl FOR VALUES FROM (1) TO (100);
CREATE TABLE part_tbl_2 PARTITION OF part_tbl FOR VALUES FROM (100) TO (200);
CREATE INDEX ON part_tbl(data);
SELECT c.relname, i.indisvisible
FROM pg_index i
JOIN pg_class c ON i.indexrelid = c.oid
WHERE c.relname LIKE 'part_tbl%'
ORDER BY c.relname;
-----

#89Shayon Mukherjee
shayonj@gmail.com
In reply to: jian he (#87)
1 attachment(s)
Re: [PATCH] Re: Proposal to Enable/Disable Index using ALTER INDEX

On Thu, Apr 24, 2025 at 12:45 AM jian he <jian.universality@gmail.com>
wrote:

hi.
The following is a review of version 17.

ATExecSetIndexVisibility
if (indexForm->indisvisible != visible)
{
indexForm->indisvisible = visible;
CatalogTupleUpdate(pg_index, &indexTuple->t_self, indexTuple);
CacheInvalidateRelcache(heapRel);
InvokeObjectPostAlterHook(IndexRelationId, indexOid, 0);
CommandCounterIncrement();
}
I am slightly confused. if we already used
CommandCounterIncrement();
then we don't need CacheInvalidateRelcache?

Thank you for this catch. I misunderstood the behavior of the two and was
performing both to avoid inconsistency between state within a transaction
and cross session, but as you pointed out CommandCounterIncrement() helps
achieve both. Updated.

doc/src/sgml/ref/alter_index.sgml

<para>
<command>ALTER INDEX</command> changes the definition of an existing
index.
There are several subforms described below. Note that the lock level
required
may differ for each subform. An <literal>ACCESS EXCLUSIVE</literal>
lock is held
unless explicitly noted. When multiple subcommands are listed, the lock
held will be the strictest one required from any subcommand.

per the above para, we need mention that ALTER INDEX SET
INVISIBLE|INVISIBLE
only use ShareUpdateExclusiveLock?

I wasn't sure at first where to add the note about
ShareUpdateExclusiveLock. But it looks like we have a precedent from RENAME
in doc/src/sgml/ref/alter_index.sgml, so I have done the same for VISIBLE &
INVISIBLE in doc/src/sgml/ref/alter_index.sgml as well.

index_create is called in several places,
most of the time, we use INDEX_CREATE_VISIBLE.
if we define it as INDEX_CREATE_INVISIBLE rather than INDEX_CREATE_VISIBLE
then argument flags required code changes would be less, (i didn't try
it myself)

Looks like the only change we would save is the one in
src/backend/catalog/toasting.c. Rest of the code change/diffs would still
be needed IIUC (if I understand correctly). This approach felt a bit
ergonomical, hence opted for it, but happy to update. Let me know.

Similar to get_index_isclustered,

We can place GetIndexVisibility in
src/backend/utils/cache/lsyscache.c,
make it an extern function, so others can use it;
to align with other function names,
maybe rename it as get_index_visibility.

I was a bit torn on this one and figured I wouldn't introduce it as it
could be a bit of premature optimization, until there were more use cases
(or maybe one more). Plus, I figured the next time we need this info, we
could expose a more public function like get_index_visibility (given N=2, N
being the number of callers). However, given you mentioned and spotted this
as well, I have introduced get_index_visibility in the new patch now.

create index v2_idx on v1(data) visible;
is allowed,
doc/src/sgml/ref/create_index.sgml
<synopsis> section need to change to
[ VISIBLE | INVISIBLE ]

?

Updated to match the same pattern as the one in
doc/src/sgml/ref/alter_index.sgml.

Thank you for the feedback. I have also updated the feedback from [1]/messages/by-id/CACJufxFS_M7nGvFiz-dUutaWb7RQxRMO97wC5ZezKW2ZsMQPQg@mail.gmail.com as
well. Few extra notes:

- Attached v18
- Rebased against master
- Updated the commit message
- Updated the target remote version to now be fout->remoteVersion >= 190000
- Using a UNION ALL query to show all indexes from part_tbl partitioned
tables in the specs as noted in [1]/messages/by-id/CACJufxFS_M7nGvFiz-dUutaWb7RQxRMO97wC5ZezKW2ZsMQPQg@mail.gmail.com. The query suggested in [1]/messages/by-id/CACJufxFS_M7nGvFiz-dUutaWb7RQxRMO97wC5ZezKW2ZsMQPQg@mail.gmail.com wasn't
encompassing all the indexes, hence the UNION ALL for WHERE i.indrelid =
'part_tbl'::regclass::oid.

[1]: /messages/by-id/CACJufxFS_M7nGvFiz-dUutaWb7RQxRMO97wC5ZezKW2ZsMQPQg@mail.gmail.com
/messages/by-id/CACJufxFS_M7nGvFiz-dUutaWb7RQxRMO97wC5ZezKW2ZsMQPQg@mail.gmail.com

Thank you
Shayon

Attachments:

v18-0001-Introduce-the-ability-to-set-index-visibility-us.patchapplication/x-patch; name=v18-0001-Introduce-the-ability-to-set-index-visibility-us.patchDownload
From ee130c6ec2555ecdc2cb8e3eda360017507c1e4f Mon Sep 17 00:00:00 2001
From: Shayon Mukherjee <shayonj@gmail.com>
Date: Sun, 27 Apr 2025 16:37:41 -0400
Subject: [PATCH v18] Introduce the ability to set index visibility using ALTER
 INDEX

This patch introduces the ability to make an index INVISIBLE ( or VISIBLE )
to the planner, making the index not eligible for planning but will continue
to be maintained when the underlying data changes. This behavior is accomplished
by introducing new grammar ALTER INDEX ... VISIBLE|INVISIBLE and
CREATE INDEX ... VISIBLE|INVISIBLE.

Additionally, there is also support for force_invisible_index GUC parameter that forces
the planner to use invisible indexes. This is useful for testing and validating index behavior
without changing their visibility state.

Discussion: https://www.postgresql.org/message-id/flat/EF2313B8-A017-4869-9B7F-A24EDD8795DE%40gmail.com#dbe65017ffa7b65a4f3f29e64ed2fce5
---
 doc/src/sgml/catalogs.sgml                    |  11 +
 doc/src/sgml/config.sgml                      |  16 +
 doc/src/sgml/indices.sgml                     |  21 +
 doc/src/sgml/ref/alter_index.sgml             |  40 +
 doc/src/sgml/ref/create_index.sgml            |  29 +
 src/backend/bootstrap/bootparse.y             |   2 +
 src/backend/catalog/index.c                   |  31 +-
 src/backend/catalog/toasting.c                |   2 +-
 src/backend/commands/indexcmds.c              |   4 +
 src/backend/commands/tablecmds.c              |  90 +-
 src/backend/optimizer/util/plancat.c          |  30 +-
 src/backend/parser/gram.y                     |  56 +-
 src/backend/parser/parse_utilcmd.c            |   3 +
 src/backend/utils/adt/ruleutils.c             |   4 +
 src/backend/utils/cache/relcache.c            |   1 +
 src/backend/utils/misc/guc_tables.c           |  10 +
 src/backend/utils/misc/postgresql.conf.sample |   1 +
 src/bin/pg_dump/pg_dump.c                     |  21 +-
 src/bin/pg_dump/pg_dump.h                     |   2 +
 src/bin/pg_dump/t/002_pg_dump.pl              |  29 +
 src/bin/psql/describe.c                       |  15 +-
 src/bin/psql/tab-complete.in.c                |   6 +-
 src/include/catalog/index.h                   |   2 +-
 src/include/catalog/pg_index.h                |   2 +
 src/include/nodes/parsenodes.h                |   4 +
 src/include/optimizer/optimizer.h             |   5 +
 src/include/parser/kwlist.h                   |   2 +
 src/include/utils/guc_hooks.h                 |   1 +
 src/include/utils/lsyscache.h                 |   1 +
 src/interfaces/ecpg/test/regression.diffs     |   0
 src/interfaces/ecpg/test/regression.out       |  55 ++
 src/test/modules/test_ddl_deparse/Makefile    |   3 +-
 .../test_ddl_deparse/expected/alter_index.out |  29 +
 src/test/modules/test_ddl_deparse/meson.build |   1 +
 .../test_ddl_deparse/sql/alter_index.sql      |  18 +
 .../test_ddl_deparse/test_ddl_deparse.c       |   6 +
 src/test/regress/expected/create_index.out    | 827 ++++++++++++++++++
 src/test/regress/sql/create_index.sql         | 349 ++++++++
 38 files changed, 1703 insertions(+), 26 deletions(-)
 create mode 100644 src/interfaces/ecpg/test/regression.diffs
 create mode 100644 src/interfaces/ecpg/test/regression.out
 create mode 100644 src/test/modules/test_ddl_deparse/expected/alter_index.out
 create mode 100644 src/test/modules/test_ddl_deparse/sql/alter_index.sql

diff --git a/doc/src/sgml/catalogs.sgml b/doc/src/sgml/catalogs.sgml
index cbd4e40a32..3307df883b 100644
--- a/doc/src/sgml/catalogs.sgml
+++ b/doc/src/sgml/catalogs.sgml
@@ -4618,6 +4618,17 @@ SCRAM-SHA-256$<replaceable>&lt;iteration count&gt;</replaceable>:<replaceable>&l
        partial index.
       </para></entry>
      </row>
+
+     <row>
+      <entry role="catalog_table_entry"><para role="column_definition">
+       <structfield>indisvisible</structfield> <type>bool</type>
+      </para>
+      <para>
+       If true, the index is currently visible to the planner and may be used for queries.
+       If false, the index is invisible and may not be used for queries,
+       but is still updated when the table is modified. Default is true.
+      </para></entry>
+     </row>
     </tbody>
    </tgroup>
   </table>
diff --git a/doc/src/sgml/config.sgml b/doc/src/sgml/config.sgml
index 14661ac2cc..a009a16630 100644
--- a/doc/src/sgml/config.sgml
+++ b/doc/src/sgml/config.sgml
@@ -5814,6 +5814,22 @@ ANY <replaceable class="parameter">num_sync</replaceable> ( <replaceable class="
       </listitem>
      </varlistentry>
 
+     <varlistentry id="guc-force-invisible-index" xreflabel="use_invisible_index">
+      <term><varname>use_invisible_index</varname> (<type>boolean</type>)
+      <indexterm>
+       <primary><varname>use_invisible_index</varname> configuration parameter</primary>
+      </indexterm>
+      </term>
+      <listitem>
+       <para>
+        Forces the query planner to consider indexes that have been marked as invisible using
+        <command>ALTER INDEX ... INVISIBLE</command>. This parameter is useful for selective
+        use of invisible indexes in specific application contexts. The default
+        is <literal>off</literal>.
+       </para>
+      </listitem>
+     </varlistentry>
+
      </variablelist>
      </sect2>
      <sect2 id="runtime-config-query-constants">
diff --git a/doc/src/sgml/indices.sgml b/doc/src/sgml/indices.sgml
index 9c4f76abf0..97bb599a05 100644
--- a/doc/src/sgml/indices.sgml
+++ b/doc/src/sgml/indices.sgml
@@ -1673,6 +1673,27 @@ CREATE INDEX test1c_content_y_index ON test1c (content COLLATE "y");
      <productname>PostgreSQL</productname> developers to examine the issue.
     </para>
    </listitem>
+
+   <listitem>
+    <para>
+     Invisible indexes provide a convenient way to experiment with indexes
+     without needing to fully drop and recreate them. You can create a new index as
+     invisible with <command>CREATE INDEX ... INVISIBLE</command> or mark
+     an existing index invisible with <command>ALTER INDEX ... INVISIBLE</command>.
+     When an index is invisible, the planner will ignore it by default.
+     To test the index's effect on performance, set the
+     <varname>use_invisible_index</varname> parameter to <literal>on</literal>.
+     This allows you to compare query performance with and without the index
+     before making it visible to all queries with
+     <command>ALTER INDEX ... VISIBLE</command>.
+    </para>
+    <para>
+     Similarly, before dropping an existing index that appears unused,
+     consider marking it invisible to verify that query performance doesn't
+     degrade. Check <structname>pg_stat_user_indexes</structname>.<structfield>idx_scan</structfield>
+     to identify potentially unused indexes.
+    </para>
+   </listitem>
   </itemizedlist>
  </sect1>
 </chapter>
diff --git a/doc/src/sgml/ref/alter_index.sgml b/doc/src/sgml/ref/alter_index.sgml
index 1d42d05d85..08bf400099 100644
--- a/doc/src/sgml/ref/alter_index.sgml
+++ b/doc/src/sgml/ref/alter_index.sgml
@@ -31,6 +31,7 @@ ALTER INDEX [ IF EXISTS ] <replaceable class="parameter">name</replaceable> ALTE
     SET STATISTICS <replaceable class="parameter">integer</replaceable>
 ALTER INDEX ALL IN TABLESPACE <replaceable class="parameter">name</replaceable> [ OWNED BY <replaceable class="parameter">role_name</replaceable> [, ... ] ]
     SET TABLESPACE <replaceable class="parameter">new_tablespace</replaceable> [ NOWAIT ]
+ALTER INDEX [ IF EXISTS ] <replaceable class="parameter">name</replaceable> { VISIBLE | INVISIBLE }
 </synopsis>
  </refsynopsisdiv>
 
@@ -159,6 +160,31 @@ ALTER INDEX ALL IN TABLESPACE <replaceable class="parameter">name</replaceable>
     </listitem>
    </varlistentry>
 
+   <varlistentry>
+    <term><literal>VISIBLE</literal></term>
+    <listitem>
+     <para>
+      Make the specified index visible. The index will be used for query planning.
+      This operation acquires a <literal>SHARE UPDATE EXCLUSIVE</literal> lock.
+     </para>
+    </listitem>
+   </varlistentry>
+
+   <varlistentry>
+    <term><literal>INVISIBLE</literal></term>
+    <listitem>
+     <para>
+      Make the specified index invisible. The index will not be used for queries.
+      This can be useful for testing query performance with and without specific
+      indexes. If performance degrades after making an index invisible, it can be easily
+      be made visible using <literal>VISIBLE</literal>.
+     </para>
+     <para>
+      This operation acquires a <literal>SHARE UPDATE EXCLUSIVE</literal> lock.
+     </para>
+    </listitem>
+   </varlistentry>
+
   </variablelist>
   </para>
 
@@ -301,6 +327,20 @@ CREATE INDEX coord_idx ON measured (x, y, (z + t));
 ALTER INDEX coord_idx ALTER COLUMN 3 SET STATISTICS 1000;
 </programlisting></para>
 
+  <para>
+   To make an index visible:
+<programlisting>
+ALTER INDEX idx_name VISIBLE;
+</programlisting>
+  </para>
+
+  <para>
+   To make an index invisible:
+<programlisting>
+ALTER INDEX idx_name INVISIBLE;
+</programlisting>
+  </para>
+
  </refsect1>
 
  <refsect1>
diff --git a/doc/src/sgml/ref/create_index.sgml b/doc/src/sgml/ref/create_index.sgml
index 147a8f7587..539d06e3df 100644
--- a/doc/src/sgml/ref/create_index.sgml
+++ b/doc/src/sgml/ref/create_index.sgml
@@ -28,6 +28,7 @@ CREATE [ UNIQUE ] INDEX [ CONCURRENTLY ] [ [ IF NOT EXISTS ] <replaceable class=
     [ WITH ( <replaceable class="parameter">storage_parameter</replaceable> [= <replaceable class="parameter">value</replaceable>] [, ... ] ) ]
     [ TABLESPACE <replaceable class="parameter">tablespace_name</replaceable> ]
     [ WHERE <replaceable class="parameter">predicate</replaceable> ]
+    [ VISIBLE | INVISIBLE ]
 </synopsis>
  </refsynopsisdiv>
 
@@ -380,6 +381,19 @@ CREATE [ UNIQUE ] INDEX [ CONCURRENTLY ] [ [ IF NOT EXISTS ] <replaceable class=
       </listitem>
      </varlistentry>
 
+    <varlistentry>
+      <term><literal>INVISIBLE</literal></term>
+      <listitem>
+       <para>
+        Creates the index in an invisible state (default visible). An invisible index is
+        not used by the query planner for queries, but it is still maintained
+        when the underlying table data changes. This can be useful when you want to create
+        an index without immediately impacting query planning, allowing you to make it
+        visible later at a more convenient time. The index can be made visible later
+        using <command>ALTER INDEX ... VISIBLE</command>.
+       </para>
+      </listitem>
+     </varlistentry>
     </variablelist>
 
   <refsect2 id="sql-createindex-storage-parameters" xreflabel="Index Storage Parameters">
@@ -707,6 +721,14 @@ Indexes:
     partitioned index is a metadata only operation.
    </para>
 
+  <para>
+   When creating an index with the <literal>INVISIBLE</literal> option, the index
+   will be created but not used for query planning. This can be useful for
+   preparing an index in advance of its use, or for testing purposes. The index
+   will still be maintained as the table is modified, so it can be made visible
+   later without needing to be rebuilt. By default all new indexes are visible.
+  </para>
+
   </refsect2>
  </refsect1>
 
@@ -986,6 +1008,13 @@ SELECT * FROM points
 CREATE INDEX CONCURRENTLY sales_quantity_index ON sales_table (quantity);
 </programlisting></para>
 
+  <para>
+   To create an index on the table <literal>test_table</literal> with the default
+   name, but have it initially invisible:
+<programlisting>
+CREATE INDEX ON test_table (col1) INVISIBLE;
+</programlisting>
+  </para>
  </refsect1>
 
  <refsect1>
diff --git a/src/backend/bootstrap/bootparse.y b/src/backend/bootstrap/bootparse.y
index 9833f52c1b..ea21511a20 100644
--- a/src/backend/bootstrap/bootparse.y
+++ b/src/backend/bootstrap/bootparse.y
@@ -303,6 +303,7 @@ Boot_DeclareIndexStmt:
 					stmt->concurrent = false;
 					stmt->if_not_exists = false;
 					stmt->reset_default_tblspc = false;
+					stmt->isvisible = true;
 
 					/* locks and races need not concern us in bootstrap mode */
 					relationId = RangeVarGetRelid(stmt->relation, NoLock,
@@ -356,6 +357,7 @@ Boot_DeclareUniqueIndexStmt:
 					stmt->concurrent = false;
 					stmt->if_not_exists = false;
 					stmt->reset_default_tblspc = false;
+					stmt->isvisible = true;
 
 					/* locks and races need not concern us in bootstrap mode */
 					relationId = RangeVarGetRelid(stmt->relation, NoLock,
diff --git a/src/backend/catalog/index.c b/src/backend/catalog/index.c
index 739a92bdcc..2d8ceb60ce 100644
--- a/src/backend/catalog/index.c
+++ b/src/backend/catalog/index.c
@@ -119,7 +119,8 @@ static void UpdateIndexRelation(Oid indexoid, Oid heapoid,
 								bool isexclusion,
 								bool immediate,
 								bool isvalid,
-								bool isready);
+								bool isready,
+								bool isvisible);
 static void index_update_stats(Relation rel,
 							   bool hasindex,
 							   double reltuples);
@@ -571,7 +572,8 @@ UpdateIndexRelation(Oid indexoid,
 					bool isexclusion,
 					bool immediate,
 					bool isvalid,
-					bool isready)
+					bool isready,
+					bool isvisible)
 {
 	int2vector *indkey;
 	oidvector  *indcollation;
@@ -649,6 +651,7 @@ UpdateIndexRelation(Oid indexoid,
 	values[Anum_pg_index_indisready - 1] = BoolGetDatum(isready);
 	values[Anum_pg_index_indislive - 1] = BoolGetDatum(true);
 	values[Anum_pg_index_indisreplident - 1] = BoolGetDatum(false);
+	values[Anum_pg_index_indisvisible - 1] = BoolGetDatum(isvisible);
 	values[Anum_pg_index_indkey - 1] = PointerGetDatum(indkey);
 	values[Anum_pg_index_indcollation - 1] = PointerGetDatum(indcollation);
 	values[Anum_pg_index_indclass - 1] = PointerGetDatum(indclass);
@@ -714,6 +717,8 @@ UpdateIndexRelation(Oid indexoid,
  *			already exists.
  *		INDEX_CREATE_PARTITIONED:
  *			create a partitioned index (table must be partitioned)
+ *		INDEX_CREATE_VISIBLE:
+ *			create the index as visible to query planner
  * constr_flags: flags passed to index_constraint_create
  *		(only if INDEX_CREATE_ADD_CONSTRAINT is set)
  * allow_system_table_mods: allow table to be a system catalog
@@ -759,6 +764,7 @@ index_create(Relation heapRelation,
 	bool		invalid = (flags & INDEX_CREATE_INVALID) != 0;
 	bool		concurrent = (flags & INDEX_CREATE_CONCURRENT) != 0;
 	bool		partitioned = (flags & INDEX_CREATE_PARTITIONED) != 0;
+	bool		isvisible = (flags & INDEX_CREATE_VISIBLE) != 0;
 	char		relkind;
 	TransactionId relfrozenxid;
 	MultiXactId relminmxid;
@@ -1042,13 +1048,15 @@ index_create(Relation heapRelation,
 	 *	  (Or, could define a rule to maintain the predicate) --Nels, Feb '92
 	 * ----------------
 	 */
+
 	UpdateIndexRelation(indexRelationId, heapRelationId, parentIndexRelid,
 						indexInfo,
 						collationIds, opclassIds, coloptions,
 						isprimary, is_exclusion,
 						(constr_flags & INDEX_CONSTR_CREATE_DEFERRABLE) == 0,
 						!concurrent && !invalid,
-						!concurrent);
+						!concurrent,
+						isvisible);
 
 	/*
 	 * Register relcache invalidation on the indexes' heap relation, to
@@ -1317,6 +1325,8 @@ index_concurrently_create_copy(Relation heapRelation, Oid oldIndexId,
 	List	   *indexColNames = NIL;
 	List	   *indexExprs = NIL;
 	List	   *indexPreds = NIL;
+	Form_pg_index indexForm;
+	bits16		createFlags;
 
 	indexRelation = index_open(oldIndexId, RowExclusiveLock);
 
@@ -1344,6 +1354,9 @@ index_concurrently_create_copy(Relation heapRelation, Oid oldIndexId,
 											Anum_pg_index_indoption);
 	indcoloptions = (int2vector *) DatumGetPointer(colOptionDatum);
 
+	/* Get the visibility state of the original index */
+	indexForm = (Form_pg_index) GETSTRUCT(indexTuple);
+
 	/* Fetch reloptions of index if any */
 	classTuple = SearchSysCache1(RELOID, ObjectIdGetDatum(oldIndexId));
 	if (!HeapTupleIsValid(classTuple))
@@ -1435,6 +1448,16 @@ index_concurrently_create_copy(Relation heapRelation, Oid oldIndexId,
 		stattargets[i].isnull = isnull;
 	}
 
+	/*
+	 * Determine the create flags for the new index. We always use SKIP_BUILD
+	 * and CONCURRENT for concurrent reindexing. If the original index was
+	 * visible, we also set the VISIBLE flag to maintain the same state in the
+	 * new index.
+	 */
+	createFlags = INDEX_CREATE_SKIP_BUILD | INDEX_CREATE_CONCURRENT;
+	if (indexForm->indisvisible)
+		createFlags |= INDEX_CREATE_VISIBLE;
+
 	/*
 	 * Now create the new index.
 	 *
@@ -1458,7 +1481,7 @@ index_concurrently_create_copy(Relation heapRelation, Oid oldIndexId,
 							  indcoloptions->values,
 							  stattargets,
 							  reloptionsDatum,
-							  INDEX_CREATE_SKIP_BUILD | INDEX_CREATE_CONCURRENT,
+							  createFlags,
 							  0,
 							  true, /* allow table to be a system catalog? */
 							  false,	/* is_internal? */
diff --git a/src/backend/catalog/toasting.c b/src/backend/catalog/toasting.c
index 874a8fc89a..7721d16fd3 100644
--- a/src/backend/catalog/toasting.c
+++ b/src/backend/catalog/toasting.c
@@ -325,7 +325,7 @@ create_toast_table(Relation rel, Oid toastOid, Oid toastIndexOid,
 				 BTREE_AM_OID,
 				 rel->rd_rel->reltablespace,
 				 collationIds, opclassIds, NULL, coloptions, NULL, (Datum) 0,
-				 INDEX_CREATE_IS_PRIMARY, 0, true, true, NULL);
+				 INDEX_CREATE_IS_PRIMARY | INDEX_CREATE_VISIBLE, 0, true, true, NULL);
 
 	table_close(toast_rel, NoLock);
 
diff --git a/src/backend/commands/indexcmds.c b/src/backend/commands/indexcmds.c
index 33c2106c17..693f23e8d6 100644
--- a/src/backend/commands/indexcmds.c
+++ b/src/backend/commands/indexcmds.c
@@ -1222,6 +1222,10 @@ DefineIndex(Oid tableId,
 		flags |= INDEX_CREATE_PARTITIONED;
 	if (stmt->primary)
 		flags |= INDEX_CREATE_IS_PRIMARY;
+	if (stmt->isvisible)
+		flags |= INDEX_CREATE_VISIBLE;
+	else
+		flags &= ~INDEX_CREATE_VISIBLE;
 
 	/*
 	 * If the table is partitioned, and recursion was declined but partitions
diff --git a/src/backend/commands/tablecmds.c b/src/backend/commands/tablecmds.c
index 2705cf1133..adbf9ccd55 100644
--- a/src/backend/commands/tablecmds.c
+++ b/src/backend/commands/tablecmds.c
@@ -739,7 +739,7 @@ static List *GetParentedForeignKeyRefs(Relation partition);
 static void ATDetachCheckNoForeignKeyRefs(Relation partition);
 static char GetAttributeCompression(Oid atttypid, const char *compression);
 static char GetAttributeStorage(Oid atttypid, const char *storagemode);
-
+static void ATExecSetIndexVisibility(Relation rel, bool visible);
 
 /* ----------------------------------------------------------------
  *		DefineRelation
@@ -4834,6 +4834,11 @@ AlterTableGetLockLevel(List *cmds)
 				cmd_lockmode = ShareUpdateExclusiveLock;
 				break;
 
+			case AT_SetIndexVisible:
+			case AT_SetIndexInvisible:
+				cmd_lockmode = ShareUpdateExclusiveLock;
+				break;
+
 			default:			/* oops */
 				elog(ERROR, "unrecognized alter table type: %d",
 					 (int) cmd->subtype);
@@ -5269,6 +5274,13 @@ ATPrepCmd(List **wqueue, Relation rel, AlterTableCmd *cmd,
 			/* No command-specific prep needed */
 			pass = AT_PASS_MISC;
 			break;
+		case AT_SetIndexVisible:
+		case AT_SetIndexInvisible:
+			ATSimplePermissions(cmd->subtype, rel, ATT_INDEX | ATT_PARTITIONED_INDEX);
+			ATSimpleRecursion(wqueue, rel, cmd, true, lockmode, context);
+			/* No command-specific prep needed */
+			pass = AT_PASS_MISC;
+			break;
 		default:				/* oops */
 			elog(ERROR, "unrecognized alter table type: %d",
 				 (int) cmd->subtype);
@@ -5665,6 +5677,12 @@ ATExecCmd(List **wqueue, AlteredTableInfo *tab,
 		case AT_DetachPartitionFinalize:
 			address = ATExecDetachPartitionFinalize(rel, ((PartitionCmd *) cmd->def)->name);
 			break;
+		case AT_SetIndexVisible:
+			ATExecSetIndexVisibility(rel, true);
+			break;
+		case AT_SetIndexInvisible:
+			ATExecSetIndexVisibility(rel, false);
+			break;
 		default:				/* oops */
 			elog(ERROR, "unrecognized alter table type: %d",
 				 (int) cmd->subtype);
@@ -6615,6 +6633,8 @@ alter_table_type_to_string(AlterTableType cmdtype)
 			return "DROP COLUMN";
 		case AT_AddIndex:
 		case AT_ReAddIndex:
+		case AT_SetIndexVisible:
+		case AT_SetIndexInvisible:
 			return NULL;		/* not real grammar */
 		case AT_AddConstraint:
 		case AT_ReAddConstraint:
@@ -15627,6 +15647,8 @@ ATPostAlterTypeParse(Oid oldId, Oid oldRelId, Oid refRelId, char *cmd,
 			stmt->reset_default_tblspc = true;
 			/* keep the index's comment */
 			stmt->idxcomment = GetComment(oldId, RelationRelationId, 0);
+			/* preserve the index's visibility status */
+			stmt->isvisible = get_index_visibility(oldId);
 
 			newcmd = makeNode(AlterTableCmd);
 			newcmd->subtype = AT_ReAddIndex;
@@ -15657,6 +15679,8 @@ ATPostAlterTypeParse(Oid oldId, Oid oldRelId, Oid refRelId, char *cmd,
 					indstmt->idxcomment = GetComment(indoid,
 													 RelationRelationId, 0);
 					indstmt->reset_default_tblspc = true;
+					/* preserve the index's visibility status */
+					indstmt->isvisible = get_index_visibility(indoid);
 
 					cmd->subtype = AT_ReAddIndex;
 					tab->subcmds[AT_PASS_OLD_INDEX] =
@@ -22014,3 +22038,67 @@ GetAttributeStorage(Oid atttypid, const char *storagemode)
 
 	return cstorage;
 }
+
+/*
+ * ATExecSetIndexVisibility
+ * Performs a catalog update to mark an index as visible or invisible in pg_index.
+ */
+static void
+ATExecSetIndexVisibility(Relation rel, bool visible)
+{
+	Oid			indexOid = RelationGetRelid(rel);
+	Oid			heapOid;
+	Relation	pg_index;
+	Relation	heapRel;
+	HeapTuple	indexTuple;
+	Form_pg_index indexForm;
+
+	heapOid = IndexGetRelation(indexOid, false);
+	heapRel = table_open(heapOid, AccessShareLock);
+	pg_index = table_open(IndexRelationId, RowExclusiveLock);
+
+	indexTuple = SearchSysCacheCopy1(INDEXRELID, ObjectIdGetDatum(indexOid));
+	if (!HeapTupleIsValid(indexTuple))
+		elog(ERROR, "cache lookup failed for index %u", indexOid);
+
+	indexForm = (Form_pg_index) GETSTRUCT(indexTuple);
+	if (indexForm->indcheckxmin)
+		ereport(ERROR,
+				errcode(ERRCODE_OBJECT_NOT_IN_PREREQUISITE_STATE),
+				errmsg("cannot update index visibility while indcheckxmin is true"),
+				errhint("Wait for all transactions that might see inconsistent HOT chains to complete"));
+
+	if (indexForm->indisvisible != visible)
+	{
+		indexForm->indisvisible = visible;
+		CatalogTupleUpdate(pg_index, &indexTuple->t_self, indexTuple);
+
+		InvokeObjectPostAlterHook(IndexRelationId, indexOid, 0);
+		CommandCounterIncrement();
+	}
+
+	heap_freetuple(indexTuple);
+	table_close(pg_index, RowExclusiveLock);
+	table_close(heapRel, AccessShareLock);
+}
+
+/*
+* Get index visibility status from pg_index
+*/
+bool
+get_index_visibility(Oid indexOid)
+{
+	HeapTuple	indexTuple;
+	Form_pg_index indexForm;
+	bool		isvisible;
+
+	indexTuple = SearchSysCache1(INDEXRELID, ObjectIdGetDatum(indexOid));
+	if (!HeapTupleIsValid(indexTuple))
+		elog(ERROR, "cache lookup failed for index %u", indexOid);
+
+	indexForm = (Form_pg_index) GETSTRUCT(indexTuple);
+	isvisible = indexForm->indisvisible;
+	ReleaseSysCache(indexTuple);
+
+	return isvisible;
+}
diff --git a/src/backend/optimizer/util/plancat.c b/src/backend/optimizer/util/plancat.c
index 59233b6473..6d938d3589 100644
--- a/src/backend/optimizer/util/plancat.c
+++ b/src/backend/optimizer/util/plancat.c
@@ -47,7 +47,9 @@
 #include "storage/bufmgr.h"
 #include "tcop/tcopprot.h"
 #include "utils/builtins.h"
+#include "utils/guc_hooks.h"
 #include "utils/lsyscache.h"
+#include "utils/plancache.h"
 #include "utils/partcache.h"
 #include "utils/rel.h"
 #include "utils/snapmgr.h"
@@ -55,6 +57,7 @@
 
 /* GUC parameter */
 int			constraint_exclusion = CONSTRAINT_EXCLUSION_PARTITION;
+bool		use_invisible_index = false;
 
 /* Hook for plugins to get control in get_relation_info() */
 get_relation_info_hook_type get_relation_info_hook = NULL;
@@ -256,13 +259,13 @@ get_relation_info(PlannerInfo *root, Oid relationObjectId, bool inhparent,
 			index = indexRelation->rd_index;
 
 			/*
-			 * Ignore invalid indexes, since they can't safely be used for
-			 * queries.  Note that this is OK because the data structure we
-			 * are constructing is only used by the planner --- the executor
-			 * still needs to insert into "invalid" indexes, if they're marked
-			 * indisready.
+			 * Skip invalid indexes, and invisible indexes unless
+			 * use_invisible_index is set. This is OK because the data
+			 * structure we are constructing is only used by the planner - the
+			 * executor still needs to insert into these indexes if they're
+			 * marked indisready.
 			 */
-			if (!index->indisvalid)
+			if (!index->indisvalid || (!index->indisvisible && !use_invisible_index))
 			{
 				index_close(indexRelation, NoLock);
 				continue;
@@ -2612,3 +2615,18 @@ set_baserel_partition_constraint(Relation relation, RelOptInfo *rel)
 		rel->partition_qual = partconstr;
 	}
 }
+
+/*
+ * assign_use_invisible_index
+ * GUC assign_hook for "use_invisible_index" GUC variable.
+ * Resets the plan cache when the value changes.
+ */
+void
+assign_use_invisible_index(bool newval, void *extra)
+{
+	if (use_invisible_index != newval)
+	{
+		use_invisible_index = newval;
+		ResetPlanCache();
+	}
+}
diff --git a/src/backend/parser/gram.y b/src/backend/parser/gram.y
index 3c4268b271..9a1b23c645 100644
--- a/src/backend/parser/gram.y
+++ b/src/backend/parser/gram.y
@@ -324,7 +324,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 %type <ival>	add_drop opt_asc_desc opt_nulls_order
 
 %type <node>	alter_table_cmd alter_type_cmd opt_collate_clause
-	   replica_identity partition_cmd index_partition_cmd
+	   replica_identity partition_cmd index_partition_cmd index_alter_cmd
 %type <list>	alter_table_cmds alter_type_cmds
 %type <list>    alter_identity_column_option_list
 %type <defelt>  alter_identity_column_option
@@ -491,6 +491,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 %type <boolean> opt_unique opt_verbose opt_full
 %type <boolean> opt_freeze opt_analyze opt_default
 %type <defelt>	opt_binary copy_delimiter
+%type <boolean>  opt_index_visibility
 
 %type <boolean> copy_from opt_program
 
@@ -733,7 +734,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 	IDENTITY_P IF_P ILIKE IMMEDIATE IMMUTABLE IMPLICIT_P IMPORT_P IN_P INCLUDE
 	INCLUDING INCREMENT INDENT INDEX INDEXES INHERIT INHERITS INITIALLY INLINE_P
 	INNER_P INOUT INPUT_P INSENSITIVE INSERT INSTEAD INT_P INTEGER
-	INTERSECT INTERVAL INTO INVOKER IS ISNULL ISOLATION
+	INTERSECT INTERVAL INTO INVISIBLE INVOKER IS ISNULL ISOLATION
 
 	JOIN JSON JSON_ARRAY JSON_ARRAYAGG JSON_EXISTS JSON_OBJECT JSON_OBJECTAGG
 	JSON_QUERY JSON_SCALAR JSON_SERIALIZE JSON_TABLE JSON_VALUE
@@ -784,7 +785,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 	UNLISTEN UNLOGGED UNTIL UPDATE USER USING
 
 	VACUUM VALID VALIDATE VALIDATOR VALUE_P VALUES VARCHAR VARIADIC VARYING
-	VERBOSE VERSION_P VIEW VIEWS VIRTUAL VOLATILE
+	VERBOSE VERSION_P VIEW VIEWS VIRTUAL VISIBLE VOLATILE
 
 	WHEN WHERE WHITESPACE_P WINDOW WITH WITHIN WITHOUT WORK WRAPPER WRITE
 
@@ -2157,6 +2158,24 @@ AlterTableStmt:
 					n->nowait = $13;
 					$$ = (Node *) n;
 				}
+		| ALTER INDEX qualified_name index_alter_cmd
+				{
+					AlterTableStmt *n = makeNode(AlterTableStmt);
+					n->relation = $3;
+					n->cmds = list_make1($4);
+					n->objtype = OBJECT_INDEX;
+					n->missing_ok = false;
+					$$ = (Node *) n;
+				}
+		| ALTER INDEX IF_P EXISTS qualified_name index_alter_cmd
+				{
+					AlterTableStmt *n = makeNode(AlterTableStmt);
+					n->relation = $5;
+					n->cmds = list_make1($6);
+					n->objtype = OBJECT_INDEX;
+					n->missing_ok = true;
+					$$ = (Node *) n;
+				}
 		|	ALTER INDEX qualified_name alter_table_cmds
 				{
 					AlterTableStmt *n = makeNode(AlterTableStmt);
@@ -2382,6 +2401,21 @@ index_partition_cmd:
 				}
 		;
 
+index_alter_cmd:
+		/* ALTER INDEX <name> VISIBLE|INVISIBLE */
+		VISIBLE
+			{
+				AlterTableCmd *n = makeNode(AlterTableCmd);
+				n->subtype = AT_SetIndexVisible;
+				$$ = (Node *) n;
+			}
+		| INVISIBLE
+			{
+				AlterTableCmd *n = makeNode(AlterTableCmd);
+				n->subtype = AT_SetIndexInvisible;
+				$$ = (Node *) n;
+			}
+		;
 alter_table_cmd:
 			/* ALTER TABLE <name> ADD <coldef> */
 			ADD_P columnDef
@@ -8190,7 +8224,7 @@ defacl_privilege_target:
 
 IndexStmt:	CREATE opt_unique INDEX opt_concurrently opt_single_name
 			ON relation_expr access_method_clause '(' index_params ')'
-			opt_include opt_unique_null_treatment opt_reloptions OptTableSpace where_clause
+			opt_include opt_unique_null_treatment opt_reloptions OptTableSpace where_clause opt_index_visibility
 				{
 					IndexStmt *n = makeNode(IndexStmt);
 
@@ -8205,6 +8239,7 @@ IndexStmt:	CREATE opt_unique INDEX opt_concurrently opt_single_name
 					n->options = $14;
 					n->tableSpace = $15;
 					n->whereClause = $16;
+					n->isvisible = $17;
 					n->excludeOpNames = NIL;
 					n->idxcomment = NULL;
 					n->indexOid = InvalidOid;
@@ -8222,7 +8257,7 @@ IndexStmt:	CREATE opt_unique INDEX opt_concurrently opt_single_name
 				}
 			| CREATE opt_unique INDEX opt_concurrently IF_P NOT EXISTS name
 			ON relation_expr access_method_clause '(' index_params ')'
-			opt_include opt_unique_null_treatment opt_reloptions OptTableSpace where_clause
+			opt_include opt_unique_null_treatment opt_reloptions OptTableSpace where_clause opt_index_visibility
 				{
 					IndexStmt *n = makeNode(IndexStmt);
 
@@ -8237,6 +8272,7 @@ IndexStmt:	CREATE opt_unique INDEX opt_concurrently opt_single_name
 					n->options = $17;
 					n->tableSpace = $18;
 					n->whereClause = $19;
+					n->isvisible = $20;
 					n->excludeOpNames = NIL;
 					n->idxcomment = NULL;
 					n->indexOid = InvalidOid;
@@ -8259,6 +8295,12 @@ opt_unique:
 			| /*EMPTY*/								{ $$ = false; }
 		;
 
+opt_index_visibility:
+			VISIBLE                       { $$ = true; }
+			| INVISIBLE                   { $$ = false; }
+			| /*EMPTY*/                   { $$ = true; }
+		;
+
 access_method_clause:
 			USING name								{ $$ = $2; }
 			| /*EMPTY*/								{ $$ = DEFAULT_INDEX_TYPE; }
@@ -17836,6 +17878,7 @@ unreserved_keyword:
 			| INSENSITIVE
 			| INSERT
 			| INSTEAD
+			| INVISIBLE
 			| INVOKER
 			| ISOLATION
 			| KEEP
@@ -18022,6 +18065,7 @@ unreserved_keyword:
 			| VIEW
 			| VIEWS
 			| VIRTUAL
+			| VISIBLE
 			| VOLATILE
 			| WHITESPACE_P
 			| WITHIN
@@ -18431,6 +18475,7 @@ bare_label_keyword:
 			| INT_P
 			| INTEGER
 			| INTERVAL
+			| INVISIBLE
 			| INVOKER
 			| IS
 			| ISOLATION
@@ -18679,6 +18724,7 @@ bare_label_keyword:
 			| VIEW
 			| VIEWS
 			| VIRTUAL
+			| VISIBLE
 			| VOLATILE
 			| WHEN
 			| WHITESPACE_P
diff --git a/src/backend/parser/parse_utilcmd.c b/src/backend/parser/parse_utilcmd.c
index 62015431fd..0619833c09 100644
--- a/src/backend/parser/parse_utilcmd.c
+++ b/src/backend/parser/parse_utilcmd.c
@@ -1745,6 +1745,7 @@ generateClonedIndexStmt(RangeVar *heapRel, Relation source_idx,
 	index->concurrent = false;
 	index->if_not_exists = false;
 	index->reset_default_tblspc = false;
+	index->isvisible = idxrec->indisvisible;
 
 	/*
 	 * We don't try to preserve the name of the source index; instead, just
@@ -2366,6 +2367,8 @@ transformIndexConstraint(Constraint *constraint, CreateStmtContext *cxt)
 	index->concurrent = false;
 	index->if_not_exists = false;
 	index->reset_default_tblspc = constraint->reset_default_tblspc;
+	/* Ensure indexes for constraints are created as visible by default */
+	index->isvisible = true;
 
 	/*
 	 * If it's ALTER TABLE ADD CONSTRAINT USING INDEX, look up the index and
diff --git a/src/backend/utils/adt/ruleutils.c b/src/backend/utils/adt/ruleutils.c
index 467b08198b..77b8f47cb2 100644
--- a/src/backend/utils/adt/ruleutils.c
+++ b/src/backend/utils/adt/ruleutils.c
@@ -1565,6 +1565,10 @@ pg_get_indexdef_worker(Oid indexrelid, int colno,
 			else
 				appendStringInfo(&buf, " WHERE %s", str);
 		}
+
+		/* Add INVISIBLE clause if the index is invisible */
+		if (!idxrec->indisvisible)
+			appendStringInfoString(&buf, " INVISIBLE");
 	}
 
 	/* Clean up */
diff --git a/src/backend/utils/cache/relcache.c b/src/backend/utils/cache/relcache.c
index 68ff67de54..3256bca61c 100644
--- a/src/backend/utils/cache/relcache.c
+++ b/src/backend/utils/cache/relcache.c
@@ -2360,6 +2360,7 @@ RelationReloadIndexInfo(Relation relation)
 		relation->rd_index->indisready = index->indisready;
 		relation->rd_index->indislive = index->indislive;
 		relation->rd_index->indisreplident = index->indisreplident;
+		relation->rd_index->indisvisible = index->indisvisible;
 
 		/* Copy xmin too, as that is needed to make sense of indcheckxmin */
 		HeapTupleHeaderSetXmin(relation->rd_indextuple->t_data,
diff --git a/src/backend/utils/misc/guc_tables.c b/src/backend/utils/misc/guc_tables.c
index 2f8cbd8675..ea2937ac2c 100644
--- a/src/backend/utils/misc/guc_tables.c
+++ b/src/backend/utils/misc/guc_tables.c
@@ -2142,6 +2142,16 @@ struct config_bool ConfigureNamesBool[] =
 		true,
 		NULL, NULL, NULL
 	},
+	{
+		{"use_invisible_index", PGC_USERSET, QUERY_TUNING_OTHER,
+			gettext_noop("Forces the planner to consider invisible indexes."),
+			NULL,
+			GUC_EXPLAIN
+		},
+		&use_invisible_index,
+		false,
+		NULL, assign_use_invisible_index, NULL
+	},
 
 	/* End-of-list marker */
 	{
diff --git a/src/backend/utils/misc/postgresql.conf.sample b/src/backend/utils/misc/postgresql.conf.sample
index 34826d0138..87ae58022d 100644
--- a/src/backend/utils/misc/postgresql.conf.sample
+++ b/src/backend/utils/misc/postgresql.conf.sample
@@ -432,6 +432,7 @@
 #enable_group_by_reordering = on
 #enable_distinct_reordering = on
 #enable_self_join_elimination = on
+#use_invisible_index = off		# forces planner to consider invisible indexes
 
 # - Planner Cost Constants -
 
diff --git a/src/bin/pg_dump/pg_dump.c b/src/bin/pg_dump/pg_dump.c
index 105e917aa7..4be1a24d6f 100644
--- a/src/bin/pg_dump/pg_dump.c
+++ b/src/bin/pg_dump/pg_dump.c
@@ -7647,7 +7647,8 @@ getIndexes(Archive *fout, TableInfo tblinfo[], int numTables)
 				i_tablespace,
 				i_indreloptions,
 				i_indstatcols,
-				i_indstatvals;
+				i_indstatvals,
+				i_indisvisible;
 
 	/*
 	 * We want to perform just one query against pg_index.  However, we
@@ -7690,7 +7691,7 @@ getIndexes(Archive *fout, TableInfo tblinfo[], int numTables)
 
 	appendPQExpBufferStr(query,
 						 "pg_catalog.pg_get_indexdef(i.indexrelid) AS indexdef, "
-						 "i.indkey, i.indisclustered, "
+						 "i.indkey, i.indisclustered, i.indisvisible, "
 						 "c.contype, c.conname, "
 						 "c.condeferrable, c.condeferred, "
 						 "c.tableoid AS contableoid, "
@@ -7712,6 +7713,13 @@ getIndexes(Archive *fout, TableInfo tblinfo[], int numTables)
 		appendPQExpBufferStr(query,
 							 "false AS indisreplident, ");
 
+	if (fout->remoteVersion >= 190000)
+		appendPQExpBufferStr(query,
+							 "i.indisvisible, ");
+	else
+		appendPQExpBufferStr(query,
+							 "true AS indisvisible, ");
+
 	if (fout->remoteVersion >= 110000)
 		appendPQExpBufferStr(query,
 							 "inh.inhparent AS parentidx, "
@@ -7826,6 +7834,7 @@ getIndexes(Archive *fout, TableInfo tblinfo[], int numTables)
 	i_indreloptions = PQfnumber(res, "indreloptions");
 	i_indstatcols = PQfnumber(res, "indstatcols");
 	i_indstatvals = PQfnumber(res, "indstatvals");
+	i_indisvisible = PQfnumber(res, "indisvisible");
 
 	indxinfo = (IndxInfo *) pg_malloc(ntups * sizeof(IndxInfo));
 
@@ -7916,7 +7925,7 @@ getIndexes(Archive *fout, TableInfo tblinfo[], int numTables)
 								  &indAttNames, &nindAttNames))
 					pg_fatal("could not parse %s array", "indattnames");
 			}
-
+			indxinfo[j].indisvisible = (PQgetvalue(res, j, i_indisvisible)[0] == 't');
 			relstats = getRelationStatistics(fout, &indxinfo[j].dobj, relpages,
 											 PQgetvalue(res, j, i_reltuples),
 											 relallvisible, relallfrozen, indexkind,
@@ -18231,6 +18240,12 @@ dumpConstraint(Archive *fout, const ConstraintInfo *coninfo)
 			}
 
 			appendPQExpBufferStr(q, ";\n");
+
+			if (!indxinfo->indisvisible)
+			{
+				appendPQExpBuffer(q, "ALTER INDEX %s INVISIBLE;\n",
+								  fmtQualifiedDumpable(indxinfo));
+			}
 		}
 
 		/*
diff --git a/src/bin/pg_dump/pg_dump.h b/src/bin/pg_dump/pg_dump.h
index b426b5e473..55d0203df3 100644
--- a/src/bin/pg_dump/pg_dump.h
+++ b/src/bin/pg_dump/pg_dump.h
@@ -427,6 +427,8 @@ typedef struct _indxInfo
 
 	/* if there is an associated constraint object, its dumpId: */
 	DumpId		indexconstraint;
+
+	bool		indisvisible;
 } IndxInfo;
 
 typedef struct _indexAttachInfo
diff --git a/src/bin/pg_dump/t/002_pg_dump.pl b/src/bin/pg_dump/t/002_pg_dump.pl
index 6c03eca8e5..4bc579eb49 100644
--- a/src/bin/pg_dump/t/002_pg_dump.pl
+++ b/src/bin/pg_dump/t/002_pg_dump.pl
@@ -2185,6 +2185,35 @@ my %tests = (
 		like => {},
 	},
 
+	'ALTER TABLE ONLY test_table ADD CONSTRAINT ... PRIMARY KEY INVISIBLE' => {
+		create_order => 97,
+		create_sql => 'CREATE TABLE dump_test.test_table_invisible (
+					   id int PRIMARY KEY
+					  );
+					  ALTER INDEX dump_test.test_table_invisible_pkey INVISIBLE;',
+		regexp => qr/^
+			\QALTER TABLE ONLY dump_test.test_table_invisible\E\n\s+
+			\QADD CONSTRAINT test_table_invisible_pkey PRIMARY KEY (id);\E\n
+			\QALTER INDEX dump_test.test_table_invisible_pkey INVISIBLE;\E
+			/xm,
+		like => { %full_runs, %dump_test_schema_runs, section_post_data => 1 },
+		unlike => { exclude_dump_test_schema => 1, only_dump_measurement => 1 },
+	},
+
+	'CREATE INDEX ... INVISIBLE' => {
+		create_order => 98,
+		create_sql => 'CREATE TABLE dump_test.test_table_mixed_indexes (
+					   id int,
+					   value int
+					  );
+					  CREATE INDEX idx_visible ON dump_test.test_table_mixed_indexes(value);
+					  CREATE UNIQUE INDEX idx_invisible ON dump_test.test_table_mixed_indexes(value) INVISIBLE;
+					  ALTER INDEX dump_test.idx_invisible INVISIBLE;',
+		regexp => qr/CREATE UNIQUE INDEX idx_invisible ON dump_test\.test_table_mixed_indexes USING btree \(value\) INVISIBLE;/m,
+		like => { %full_runs, %dump_test_schema_runs, section_post_data => 1 },
+		unlike => { exclude_dump_test_schema => 1, only_dump_measurement => 1 },
+	},
+
 	'CREATE AGGREGATE dump_test.newavg' => {
 		create_order => 25,
 		create_sql => 'CREATE AGGREGATE dump_test.newavg (
diff --git a/src/bin/psql/describe.c b/src/bin/psql/describe.c
index 1d08268393..bdb7397814 100644
--- a/src/bin/psql/describe.c
+++ b/src/bin/psql/describe.c
@@ -2329,6 +2329,11 @@ describeOneTableDetails(const char *schemaname,
 		else
 			appendPQExpBufferStr(&buf, "false AS indnullsnotdistinct,\n");
 
+		if (pset.sversion >= 180000)
+			appendPQExpBufferStr(&buf, "i.indisvisible,\n");
+		else
+			appendPQExpBufferStr(&buf, "true AS indisvisible,\n");
+
 		appendPQExpBuffer(&buf, "  a.amname, c2.relname, "
 						  "pg_catalog.pg_get_expr(i.indpred, i.indrelid, true)\n"
 						  "FROM pg_catalog.pg_index i, pg_catalog.pg_class c, pg_catalog.pg_class c2, pg_catalog.pg_am a\n"
@@ -2354,9 +2359,10 @@ describeOneTableDetails(const char *schemaname,
 			char	   *deferred = PQgetvalue(result, 0, 5);
 			char	   *indisreplident = PQgetvalue(result, 0, 6);
 			char	   *indnullsnotdistinct = PQgetvalue(result, 0, 7);
-			char	   *indamname = PQgetvalue(result, 0, 8);
-			char	   *indtable = PQgetvalue(result, 0, 9);
-			char	   *indpred = PQgetvalue(result, 0, 10);
+			char	   *indisvisible = PQgetvalue(result, 0, 8);
+			char	   *indamname = PQgetvalue(result, 0, 9);
+			char	   *indtable = PQgetvalue(result, 0, 10);
+			char	   *indpred = PQgetvalue(result, 0, 11);
 
 			if (strcmp(indisprimary, "t") == 0)
 				printfPQExpBuffer(&tmpbuf, _("primary key, "));
@@ -2393,6 +2399,9 @@ describeOneTableDetails(const char *schemaname,
 			if (strcmp(indisreplident, "t") == 0)
 				appendPQExpBufferStr(&tmpbuf, _(", replica identity"));
 
+			if (strcmp(indisvisible, "t") != 0)
+				appendPQExpBufferStr(&tmpbuf, _(", invisible"));
+
 			printTableAddFooter(&cont, tmpbuf.data);
 
 			/*
diff --git a/src/bin/psql/tab-complete.in.c b/src/bin/psql/tab-complete.in.c
index c916b9299a..8bafcb0740 100644
--- a/src/bin/psql/tab-complete.in.c
+++ b/src/bin/psql/tab-complete.in.c
@@ -2419,7 +2419,8 @@ match_previous_words(int pattern_id,
 	else if (Matches("ALTER", "INDEX", MatchAny))
 		COMPLETE_WITH("ALTER COLUMN", "OWNER TO", "RENAME TO", "SET",
 					  "RESET", "ATTACH PARTITION",
-					  "DEPENDS ON EXTENSION", "NO DEPENDS ON EXTENSION");
+					  "DEPENDS ON EXTENSION", "NO DEPENDS ON EXTENSION",
+					  "INVISIBLE", "VISIBLE");
 	else if (Matches("ALTER", "INDEX", MatchAny, "ATTACH"))
 		COMPLETE_WITH("PARTITION");
 	else if (Matches("ALTER", "INDEX", MatchAny, "ATTACH", "PARTITION"))
@@ -3433,6 +3434,9 @@ match_previous_words(int pattern_id,
 			 !TailMatches("POLICY", MatchAny, MatchAny, MatchAny, MatchAny, MatchAny) &&
 			 !TailMatches("FOR", MatchAny, MatchAny, MatchAny))
 		COMPLETE_WITH("(");
+	else if (TailMatches("INDEX|CONCURRENTLY", "ON", MatchAny, "USING", MatchAny, "(*)") ||
+			 TailMatches("INDEX|CONCURRENTLY", "ON", MatchAny, "(*)"))
+		COMPLETE_WITH("VISIBLE", "INVISIBLE");
 
 	/* CREATE OR REPLACE */
 	else if (Matches("CREATE", "OR"))
diff --git a/src/include/catalog/index.h b/src/include/catalog/index.h
index 4daa8bef5e..75bef5bd88 100644
--- a/src/include/catalog/index.h
+++ b/src/include/catalog/index.h
@@ -65,6 +65,7 @@ extern void index_check_primary_key(Relation heapRel,
 #define	INDEX_CREATE_IF_NOT_EXISTS			(1 << 4)
 #define	INDEX_CREATE_PARTITIONED			(1 << 5)
 #define INDEX_CREATE_INVALID				(1 << 6)
+#define INDEX_CREATE_VISIBLE				(1 << 7)
 
 extern Oid	index_create(Relation heapRelation,
 						 const char *indexRelationName,
@@ -175,7 +176,6 @@ extern void RestoreReindexState(const void *reindexstate);
 
 extern void IndexSetParentIndex(Relation partitionIdx, Oid parentOid);
 
-
 /*
  * itemptr_encode - Encode ItemPointer as int64/int8
  *
diff --git a/src/include/catalog/pg_index.h b/src/include/catalog/pg_index.h
index 4392b9d221..ec8e5dc4bf 100644
--- a/src/include/catalog/pg_index.h
+++ b/src/include/catalog/pg_index.h
@@ -44,6 +44,8 @@ CATALOG(pg_index,2610,IndexRelationId) BKI_SCHEMA_MACRO
 	bool		indisready;		/* is this index ready for inserts? */
 	bool		indislive;		/* is this index alive at all? */
 	bool		indisreplident; /* is this index the identity for replication? */
+	bool		indisvisible BKI_DEFAULT(t);	/* is this index visible for
+												 * use by queries? */
 
 	/* variable-length fields start here, but we allow direct access to indkey */
 	int2vector	indkey BKI_FORCE_NOT_NULL;	/* column numbers of indexed cols,
diff --git a/src/include/nodes/parsenodes.h b/src/include/nodes/parsenodes.h
index 4610fc6129..92a14b82f5 100644
--- a/src/include/nodes/parsenodes.h
+++ b/src/include/nodes/parsenodes.h
@@ -2472,6 +2472,8 @@ typedef enum AlterTableType
 	AT_SetIdentity,				/* SET identity column options */
 	AT_DropIdentity,			/* DROP IDENTITY */
 	AT_ReAddStatistics,			/* internal to commands/tablecmds.c */
+	AT_SetIndexVisible,			/* Set INDEX visible */
+	AT_SetIndexInvisible,		/* Set INDEX invisible */
 } AlterTableType;
 
 typedef struct AlterTableCmd	/* one subcommand of an ALTER TABLE */
@@ -3470,6 +3472,8 @@ typedef struct IndexStmt
 	bool		if_not_exists;	/* just do nothing if index already exists? */
 	bool		reset_default_tblspc;	/* reset default_tablespace prior to
 										 * executing */
+	bool		isvisible;		/* true if VISIBLE (default), false if
+								 * INVISIBLE */
 } IndexStmt;
 
 /* ----------------------
diff --git a/src/include/optimizer/optimizer.h b/src/include/optimizer/optimizer.h
index 546828b54b..3b5ca55bae 100644
--- a/src/include/optimizer/optimizer.h
+++ b/src/include/optimizer/optimizer.h
@@ -212,4 +212,9 @@ extern List *pull_var_clause(Node *node, int flags);
 extern Node *flatten_join_alias_vars(PlannerInfo *root, Query *query, Node *node);
 extern Node *flatten_group_exprs(PlannerInfo *root, Query *query, Node *node);
 
+/*
+ * GUC to tell planner to consider invisible indexes.
+ */
+extern bool use_invisible_index;
+
 #endif							/* OPTIMIZER_H */
diff --git a/src/include/parser/kwlist.h b/src/include/parser/kwlist.h
index a4af3f717a..77da5117cb 100644
--- a/src/include/parser/kwlist.h
+++ b/src/include/parser/kwlist.h
@@ -229,6 +229,7 @@ PG_KEYWORD("integer", INTEGER, COL_NAME_KEYWORD, BARE_LABEL)
 PG_KEYWORD("intersect", INTERSECT, RESERVED_KEYWORD, AS_LABEL)
 PG_KEYWORD("interval", INTERVAL, COL_NAME_KEYWORD, BARE_LABEL)
 PG_KEYWORD("into", INTO, RESERVED_KEYWORD, AS_LABEL)
+PG_KEYWORD("invisible", INVISIBLE, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("invoker", INVOKER, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("is", IS, TYPE_FUNC_NAME_KEYWORD, BARE_LABEL)
 PG_KEYWORD("isnull", ISNULL, TYPE_FUNC_NAME_KEYWORD, AS_LABEL)
@@ -493,6 +494,7 @@ PG_KEYWORD("version", VERSION_P, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("view", VIEW, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("views", VIEWS, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("virtual", VIRTUAL, UNRESERVED_KEYWORD, BARE_LABEL)
+PG_KEYWORD("visible", VISIBLE, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("volatile", VOLATILE, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("when", WHEN, RESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("where", WHERE, RESERVED_KEYWORD, AS_LABEL)
diff --git a/src/include/utils/guc_hooks.h b/src/include/utils/guc_hooks.h
index 799fa7ace6..dd5128fd87 100644
--- a/src/include/utils/guc_hooks.h
+++ b/src/include/utils/guc_hooks.h
@@ -178,5 +178,6 @@ extern bool check_synchronized_standby_slots(char **newval, void **extra,
 extern void assign_synchronized_standby_slots(const char *newval, void *extra);
 extern bool check_idle_replication_slot_timeout(int *newval, void **extra,
 												GucSource source);
+extern void assign_use_invisible_index(bool newval, void *extra);
 
 #endif							/* GUC_HOOKS_H */
diff --git a/src/include/utils/lsyscache.h b/src/include/utils/lsyscache.h
index fa7c7e0323..b716b94c38 100644
--- a/src/include/utils/lsyscache.h
+++ b/src/include/utils/lsyscache.h
@@ -210,6 +210,7 @@ extern Oid	get_publication_oid(const char *pubname, bool missing_ok);
 extern char *get_publication_name(Oid pubid, bool missing_ok);
 extern Oid	get_subscription_oid(const char *subname, bool missing_ok);
 extern char *get_subscription_name(Oid subid, bool missing_ok);
+extern bool get_index_visibility(Oid indexOid);
 
 #define type_is_array(typid)  (get_element_type(typid) != InvalidOid)
 /* type_is_array_domain accepts both plain arrays and domains over arrays */
diff --git a/src/interfaces/ecpg/test/regression.diffs b/src/interfaces/ecpg/test/regression.diffs
new file mode 100644
index 0000000000..e69de29bb2
diff --git a/src/interfaces/ecpg/test/regression.out b/src/interfaces/ecpg/test/regression.out
new file mode 100644
index 0000000000..cb633f4d71
--- /dev/null
+++ b/src/interfaces/ecpg/test/regression.out
@@ -0,0 +1,55 @@
+# initializing database system by copying initdb template
+# using temp instance on port 65312 with PID 30031
+ok 1         - compat_informix/dec_test                  563 ms
+ok 2         - compat_informix/charfuncs                 255 ms
+ok 3         - compat_informix/rfmtdate                  355 ms
+ok 4         - compat_informix/rfmtlong                  294 ms
+ok 5         - compat_informix/rnull                     337 ms
+ok 6         - compat_informix/sqlda                     293 ms
+ok 7         - compat_informix/describe                  289 ms
+ok 8         - compat_informix/test_informix             350 ms
+ok 9         - compat_informix/test_informix2            334 ms
+ok 10        - compat_informix/intoasc                   264 ms
+ok 11        - compat_oracle/char_array                  283 ms
+ok 12        - connect/test2                             354 ms
+ok 13        - connect/test3                             346 ms
+ok 14        - connect/test4                             312 ms
+ok 15        - connect/test5                             337 ms
+ok 16        - pgtypeslib/dt_test                        332 ms
+ok 17        - pgtypeslib/dt_test2                       323 ms
+ok 18        - pgtypeslib/num_test                       323 ms
+ok 19        - pgtypeslib/num_test2                      319 ms
+ok 20        - pgtypeslib/nan_test                       324 ms
+ok 21        - preproc/array_of_struct                   279 ms
+ok 22        - preproc/pointer_to_struct                 351 ms
+ok 23        - preproc/autoprep                          346 ms
+ok 24        - preproc/comment                           295 ms
+ok 25        - preproc/cursor                            379 ms
+ok 26        - preproc/define                            349 ms
+ok 27        - preproc/init                              296 ms
+ok 28        - preproc/strings                           317 ms
+ok 29        - preproc/type                              306 ms
+ok 30        - preproc/variable                          360 ms
+ok 31        - preproc/outofscope                        340 ms
+ok 32        - preproc/whenever                          335 ms
+ok 33        - preproc/whenever_do_continue              308 ms
+ok 34        - sql/array                                 383 ms
+ok 35        - sql/binary                                329 ms
+ok 36        - sql/bytea                                 335 ms
+ok 37        - sql/code100                               351 ms
+ok 38        - sql/copystdout                            320 ms
+ok 39        - sql/createtableas                         340 ms
+ok 40        - sql/define                                335 ms
+ok 41        - sql/desc                                  339 ms
+ok 42        - sql/sqlda                                 341 ms
+ok 43        - sql/describe                              354 ms
+ok 44        - sql/dynalloc                              316 ms
+ok 45        - sql/dynalloc2                             340 ms
+ok 46        - sql/dyntest                               343 ms
+ok 47        - sql/execute                               328 ms
+ok 48        - sql/fetch                                 324 ms
+ok 49        - sql/func                                  333 ms
+ok 50        - sql/indicators                            346 ms
+ok 51        - sql/oldexec                               314 ms
+ok 52        - sql/quote                                 311 ms
+ok 53        - sql/show                                  392 ms
diff --git a/src/test/modules/test_ddl_deparse/Makefile b/src/test/modules/test_ddl_deparse/Makefile
index 3a57a95c84..747d8b5835 100644
--- a/src/test/modules/test_ddl_deparse/Makefile
+++ b/src/test/modules/test_ddl_deparse/Makefile
@@ -27,7 +27,8 @@ REGRESS = test_ddl_deparse \
 	alter_type_enum \
 	opfamily \
 	defprivs \
-	matviews
+	matviews \
+	alter_index
 
 EXTRA_INSTALL = contrib/pg_stat_statements
 
diff --git a/src/test/modules/test_ddl_deparse/expected/alter_index.out b/src/test/modules/test_ddl_deparse/expected/alter_index.out
new file mode 100644
index 0000000000..f502baf1c5
--- /dev/null
+++ b/src/test/modules/test_ddl_deparse/expected/alter_index.out
@@ -0,0 +1,29 @@
+-- Test index visibility commands
+CREATE TABLE visibility_test (id int);
+NOTICE:  DDL test: type simple, tag CREATE TABLE
+CREATE INDEX idx_vis ON visibility_test(id);
+NOTICE:  DDL test: type simple, tag CREATE INDEX
+ALTER INDEX idx_vis INVISIBLE;
+NOTICE:  DDL test: type alter table, tag ALTER INDEX
+NOTICE:    subcommand: type SET INVISIBLE desc <NULL>
+ALTER INDEX idx_vis VISIBLE;
+NOTICE:  DDL test: type alter table, tag ALTER INDEX
+NOTICE:    subcommand: type SET VISIBLE desc <NULL>
+ALTER INDEX idx_vis INVISIBLE;
+NOTICE:  DDL test: type alter table, tag ALTER INDEX
+NOTICE:    subcommand: type SET INVISIBLE desc <NULL>
+REINDEX INDEX idx_vis;
+NOTICE:  DDL test: type simple, tag REINDEX
+CREATE SCHEMA visibility_schema;
+NOTICE:  DDL test: type simple, tag CREATE SCHEMA
+CREATE TABLE visibility_schema.test2 (id int);
+NOTICE:  DDL test: type simple, tag CREATE TABLE
+CREATE INDEX idx_vis2 ON visibility_schema.test2(id);
+NOTICE:  DDL test: type simple, tag CREATE INDEX
+ALTER INDEX visibility_schema.idx_vis2 INVISIBLE;
+NOTICE:  DDL test: type alter table, tag ALTER INDEX
+NOTICE:    subcommand: type SET INVISIBLE desc <NULL>
+-- Clean up
+DROP SCHEMA visibility_schema CASCADE;
+NOTICE:  drop cascades to table visibility_schema.test2
+DROP TABLE visibility_test CASCADE;
diff --git a/src/test/modules/test_ddl_deparse/meson.build b/src/test/modules/test_ddl_deparse/meson.build
index bff65ba633..6654b5e46d 100644
--- a/src/test/modules/test_ddl_deparse/meson.build
+++ b/src/test/modules/test_ddl_deparse/meson.build
@@ -48,6 +48,7 @@ tests += {
       'opfamily',
       'defprivs',
       'matviews',
+      'alter_index',
     ],
   },
 }
diff --git a/src/test/modules/test_ddl_deparse/sql/alter_index.sql b/src/test/modules/test_ddl_deparse/sql/alter_index.sql
new file mode 100644
index 0000000000..7a34dc6692
--- /dev/null
+++ b/src/test/modules/test_ddl_deparse/sql/alter_index.sql
@@ -0,0 +1,18 @@
+-- Test index visibility commands
+CREATE TABLE visibility_test (id int);
+CREATE INDEX idx_vis ON visibility_test(id);
+
+ALTER INDEX idx_vis INVISIBLE;
+ALTER INDEX idx_vis VISIBLE;
+
+ALTER INDEX idx_vis INVISIBLE;
+REINDEX INDEX idx_vis;
+
+CREATE SCHEMA visibility_schema;
+CREATE TABLE visibility_schema.test2 (id int);
+CREATE INDEX idx_vis2 ON visibility_schema.test2(id);
+ALTER INDEX visibility_schema.idx_vis2 INVISIBLE;
+
+-- Clean up
+DROP SCHEMA visibility_schema CASCADE;
+DROP TABLE visibility_test CASCADE;
diff --git a/src/test/modules/test_ddl_deparse/test_ddl_deparse.c b/src/test/modules/test_ddl_deparse/test_ddl_deparse.c
index 193669f2bc..8d7c7e5894 100644
--- a/src/test/modules/test_ddl_deparse/test_ddl_deparse.c
+++ b/src/test/modules/test_ddl_deparse/test_ddl_deparse.c
@@ -308,6 +308,12 @@ get_altertable_subcmdinfo(PG_FUNCTION_ARGS)
 			case AT_ReAddStatistics:
 				strtype = "(re) ADD STATS";
 				break;
+			case AT_SetIndexVisible:
+				strtype = "SET VISIBLE";
+				break;
+			case AT_SetIndexInvisible:
+				strtype = "SET INVISIBLE";
+				break;
 		}
 
 		if (subcmd->recurse)
diff --git a/src/test/regress/expected/create_index.out b/src/test/regress/expected/create_index.out
index 9ade7b835e..32eb1cd76b 100644
--- a/src/test/regress/expected/create_index.out
+++ b/src/test/regress/expected/create_index.out
@@ -3542,6 +3542,833 @@ ERROR:  REINDEX SCHEMA cannot run inside a transaction block
 END;
 -- concurrently
 REINDEX SCHEMA CONCURRENTLY schema_to_reindex;
+-- Test index visibility functionality
+CREATE TABLE index_test(
+    id INT PRIMARY KEY,
+    data TEXT,
+    num INT,
+    vector INT[],
+    range INT4RANGE
+);
+INSERT INTO index_test
+SELECT
+    g,
+    'data ' || g,
+    g % 100,
+    ARRAY[g, g+1, g+2],
+    int4range(g, g+10)
+FROM generate_series(1, 1000) g;
+-- Function for testing
+CREATE FUNCTION get_data_length(text) RETURNS INT AS $$
+    SELECT length($1);
+$$ LANGUAGE SQL IMMUTABLE;
+-- Helper function to show index status
+CREATE OR REPLACE FUNCTION show_index_status(index_name text)
+RETURNS TABLE (
+    indexrelid regclass,
+    indisvalid boolean,
+    indisready boolean,
+    indislive boolean,
+    indisvisible boolean
+) AS $$
+BEGIN
+    RETURN QUERY EXECUTE format('
+        SELECT indexrelid::regclass, indisvalid, indisready, indislive, indisvisible
+        FROM pg_index
+        WHERE indexrelid = %L::regclass', index_name);
+END;
+$$ LANGUAGE plpgsql;
+-- Create and test each index type
+-- 1. Basic single-column index
+CREATE INDEX idx_single ON index_test(data);
+SELECT show_index_status('idx_single');
+  show_index_status   
+----------------------
+ (idx_single,t,t,t,t)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE data = 'data 500';
+                  QUERY PLAN                   
+-----------------------------------------------
+ Bitmap Heap Scan on index_test
+   Recheck Cond: (data = 'data 500'::text)
+   ->  Bitmap Index Scan on idx_single
+         Index Cond: (data = 'data 500'::text)
+(4 rows)
+
+ALTER INDEX idx_single INVISIBLE;
+SELECT show_index_status('idx_single');
+  show_index_status   
+----------------------
+ (idx_single,t,t,t,f)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE data = 'data 500';
+             QUERY PLAN              
+-------------------------------------
+ Seq Scan on index_test
+   Filter: (data = 'data 500'::text)
+(2 rows)
+
+ALTER INDEX idx_single VISIBLE;
+SELECT show_index_status('idx_single');
+  show_index_status   
+----------------------
+ (idx_single,t,t,t,t)
+(1 row)
+
+-- 2. Multi-column index
+CREATE INDEX idx_multi ON index_test(num, data);
+SELECT show_index_status('idx_multi');
+  show_index_status  
+---------------------
+ (idx_multi,t,t,t,t)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE num = 50 AND data > 'data 500';
+                           QUERY PLAN                           
+----------------------------------------------------------------
+ Bitmap Heap Scan on index_test
+   Recheck Cond: ((num = 50) AND (data > 'data 500'::text))
+   ->  Bitmap Index Scan on idx_multi
+         Index Cond: ((num = 50) AND (data > 'data 500'::text))
+(4 rows)
+
+ALTER INDEX idx_multi INVISIBLE;
+SELECT show_index_status('idx_multi');
+  show_index_status  
+---------------------
+ (idx_multi,t,t,t,f)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE num = 50 AND data > 'data 500';
+                      QUERY PLAN                      
+------------------------------------------------------
+ Seq Scan on index_test
+   Filter: ((data > 'data 500'::text) AND (num = 50))
+(2 rows)
+
+ALTER INDEX idx_multi VISIBLE;
+SELECT show_index_status('idx_multi');
+  show_index_status  
+---------------------
+ (idx_multi,t,t,t,t)
+(1 row)
+
+-- 3. Partial index
+CREATE INDEX idx_partial ON index_test(num) WHERE num < 50;
+SELECT show_index_status('idx_partial');
+   show_index_status   
+-----------------------
+ (idx_partial,t,t,t,t)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE num = 25;
+               QUERY PLAN               
+----------------------------------------
+ Bitmap Heap Scan on index_test
+   Recheck Cond: (num = 25)
+   ->  Bitmap Index Scan on idx_partial
+         Index Cond: (num = 25)
+(4 rows)
+
+ALTER INDEX idx_partial INVISIBLE;
+SELECT show_index_status('idx_partial');
+   show_index_status   
+-----------------------
+ (idx_partial,t,t,t,f)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE num = 25;
+              QUERY PLAN              
+--------------------------------------
+ Bitmap Heap Scan on index_test
+   Recheck Cond: (num = 25)
+   ->  Bitmap Index Scan on idx_multi
+         Index Cond: (num = 25)
+(4 rows)
+
+ALTER INDEX idx_partial VISIBLE;
+SELECT show_index_status('idx_partial');
+   show_index_status   
+-----------------------
+ (idx_partial,t,t,t,t)
+(1 row)
+
+-- 4. Expression index
+CREATE INDEX idx_expression ON index_test((lower(data)));
+SELECT show_index_status('idx_expression');
+    show_index_status     
+--------------------------
+ (idx_expression,t,t,t,t)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE lower(data) = 'data 500';
+                      QUERY PLAN                      
+------------------------------------------------------
+ Bitmap Heap Scan on index_test
+   Recheck Cond: (lower(data) = 'data 500'::text)
+   ->  Bitmap Index Scan on idx_expression
+         Index Cond: (lower(data) = 'data 500'::text)
+(4 rows)
+
+ALTER INDEX idx_expression INVISIBLE;
+SELECT show_index_status('idx_expression');
+    show_index_status     
+--------------------------
+ (idx_expression,t,t,t,f)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE lower(data) = 'data 500';
+                 QUERY PLAN                 
+--------------------------------------------
+ Seq Scan on index_test
+   Filter: (lower(data) = 'data 500'::text)
+(2 rows)
+
+ALTER INDEX idx_expression VISIBLE;
+SELECT show_index_status('idx_expression');
+    show_index_status     
+--------------------------
+ (idx_expression,t,t,t,t)
+(1 row)
+
+-- 5. GIN index
+CREATE INDEX idx_gin ON index_test USING gin(vector);
+SELECT show_index_status('idx_gin');
+ show_index_status 
+-------------------
+ (idx_gin,t,t,t,t)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE vector @> ARRAY[500];
+                     QUERY PLAN                     
+----------------------------------------------------
+ Bitmap Heap Scan on index_test
+   Recheck Cond: (vector @> '{500}'::integer[])
+   ->  Bitmap Index Scan on idx_gin
+         Index Cond: (vector @> '{500}'::integer[])
+(4 rows)
+
+ALTER INDEX idx_gin INVISIBLE;
+SELECT show_index_status('idx_gin');
+ show_index_status 
+-------------------
+ (idx_gin,t,t,t,f)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE vector @> ARRAY[500];
+                QUERY PLAN                
+------------------------------------------
+ Seq Scan on index_test
+   Filter: (vector @> '{500}'::integer[])
+(2 rows)
+
+ALTER INDEX idx_gin VISIBLE;
+SELECT show_index_status('idx_gin');
+ show_index_status 
+-------------------
+ (idx_gin,t,t,t,t)
+(1 row)
+
+-- 6. GiST index
+CREATE INDEX idx_gist ON index_test USING gist(range);
+SELECT show_index_status('idx_gist');
+ show_index_status  
+--------------------
+ (idx_gist,t,t,t,t)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE range && int4range(100, 110);
+                      QUERY PLAN                       
+-------------------------------------------------------
+ Bitmap Heap Scan on index_test
+   Recheck Cond: (range && '[100,110)'::int4range)
+   ->  Bitmap Index Scan on idx_gist
+         Index Cond: (range && '[100,110)'::int4range)
+(4 rows)
+
+ALTER INDEX idx_gist INVISIBLE;
+SELECT show_index_status('idx_gist');
+ show_index_status  
+--------------------
+ (idx_gist,t,t,t,f)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE range && int4range(100, 110);
+                 QUERY PLAN                  
+---------------------------------------------
+ Seq Scan on index_test
+   Filter: (range && '[100,110)'::int4range)
+(2 rows)
+
+ALTER INDEX idx_gist VISIBLE;
+SELECT show_index_status('idx_gist');
+ show_index_status  
+--------------------
+ (idx_gist,t,t,t,t)
+(1 row)
+
+-- 7. Covering index
+CREATE INDEX idx_covering ON index_test(num) INCLUDE (data);
+SELECT show_index_status('idx_covering');
+   show_index_status    
+------------------------
+ (idx_covering,t,t,t,t)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT num, data FROM index_test WHERE num = 50;
+               QUERY PLAN                
+-----------------------------------------
+ Bitmap Heap Scan on index_test
+   Recheck Cond: (num = 50)
+   ->  Bitmap Index Scan on idx_covering
+         Index Cond: (num = 50)
+(4 rows)
+
+ALTER INDEX idx_covering INVISIBLE;
+SELECT show_index_status('idx_covering');
+   show_index_status    
+------------------------
+ (idx_covering,t,t,t,f)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT num, data FROM index_test WHERE num = 50;
+              QUERY PLAN              
+--------------------------------------
+ Bitmap Heap Scan on index_test
+   Recheck Cond: (num = 50)
+   ->  Bitmap Index Scan on idx_multi
+         Index Cond: (num = 50)
+(4 rows)
+
+ALTER INDEX idx_covering VISIBLE;
+SELECT show_index_status('idx_covering');
+   show_index_status    
+------------------------
+ (idx_covering,t,t,t,t)
+(1 row)
+
+-- 8. Unique index
+CREATE UNIQUE INDEX idx_unique ON index_test(id, data);
+SELECT show_index_status('idx_unique');
+  show_index_status   
+----------------------
+ (idx_unique,t,t,t,t)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE id = 500 AND data = 'data 500';
+                        QUERY PLAN                        
+----------------------------------------------------------
+ Index Scan using idx_unique on index_test
+   Index Cond: ((id = 500) AND (data = 'data 500'::text))
+(2 rows)
+
+ALTER INDEX idx_unique INVISIBLE;
+SELECT show_index_status('idx_unique');
+  show_index_status   
+----------------------
+ (idx_unique,t,t,t,f)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE id = 500 AND data = 'data 500';
+                   QUERY PLAN                   
+------------------------------------------------
+ Index Scan using index_test_pkey on index_test
+   Index Cond: (id = 500)
+   Filter: (data = 'data 500'::text)
+(3 rows)
+
+ALTER INDEX idx_unique VISIBLE;
+SELECT show_index_status('idx_unique');
+  show_index_status   
+----------------------
+ (idx_unique,t,t,t,t)
+(1 row)
+
+-- 9. Function-based index
+CREATE INDEX idx_func ON index_test(get_data_length(data));
+SELECT show_index_status('idx_func');
+ show_index_status  
+--------------------
+ (idx_func,t,t,t,t)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE get_data_length(data) = 10;
+               QUERY PLAN                
+-----------------------------------------
+ Bitmap Heap Scan on index_test
+   Recheck Cond: (length(data) = 10)
+   ->  Bitmap Index Scan on idx_func
+         Index Cond: (length(data) = 10)
+(4 rows)
+
+ALTER INDEX idx_func INVISIBLE;
+SELECT show_index_status('idx_func');
+ show_index_status  
+--------------------
+ (idx_func,t,t,t,f)
+(1 row)
+
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE get_data_length(data) = 10;
+          QUERY PLAN           
+-------------------------------
+ Seq Scan on index_test
+   Filter: (length(data) = 10)
+(2 rows)
+
+ALTER INDEX idx_func VISIBLE;
+SELECT show_index_status('idx_func');
+ show_index_status  
+--------------------
+ (idx_func,t,t,t,t)
+(1 row)
+
+-- 10. Join index
+CREATE TABLE join_test (id INT PRIMARY KEY, ref_id INT);
+INSERT INTO join_test SELECT g, g % 100 FROM generate_series(1, 1000) g;
+CREATE INDEX idx_join ON join_test(ref_id);
+SELECT show_index_status('idx_join');
+ show_index_status  
+--------------------
+ (idx_join,t,t,t,t)
+(1 row)
+
+EXPLAIN (COSTS OFF)
+SELECT jt.id, it.data
+FROM join_test jt
+JOIN index_test it ON jt.ref_id = it.num
+WHERE jt.id BETWEEN 100 AND 200;
+                          QUERY PLAN                           
+---------------------------------------------------------------
+ Hash Join
+   Hash Cond: (it.num = jt.ref_id)
+   ->  Seq Scan on index_test it
+   ->  Hash
+         ->  Bitmap Heap Scan on join_test jt
+               Recheck Cond: ((id >= 100) AND (id <= 200))
+               ->  Bitmap Index Scan on join_test_pkey
+                     Index Cond: ((id >= 100) AND (id <= 200))
+(8 rows)
+
+-- Set all indexes to invisible to force seq scan
+ALTER INDEX idx_join INVISIBLE;
+ALTER INDEX join_test_pkey INVISIBLE;
+SELECT show_index_status('idx_join');
+ show_index_status  
+--------------------
+ (idx_join,t,t,t,f)
+(1 row)
+
+SELECT show_index_status('join_test_pkey');
+    show_index_status     
+--------------------------
+ (join_test_pkey,t,t,t,f)
+(1 row)
+
+EXPLAIN (COSTS OFF)
+SELECT jt.id, it.data
+FROM join_test jt
+JOIN index_test it ON jt.ref_id = it.num
+WHERE jt.id BETWEEN 100 AND 200;
+                     QUERY PLAN                      
+-----------------------------------------------------
+ Hash Join
+   Hash Cond: (it.num = jt.ref_id)
+   ->  Seq Scan on index_test it
+   ->  Hash
+         ->  Seq Scan on join_test jt
+               Filter: ((id >= 100) AND (id <= 200))
+(6 rows)
+
+ALTER INDEX idx_join VISIBLE;
+ALTER INDEX join_test_pkey VISIBLE;
+SELECT show_index_status('idx_join');
+ show_index_status  
+--------------------
+ (idx_join,t,t,t,t)
+(1 row)
+
+SELECT show_index_status('join_test_pkey');
+    show_index_status     
+--------------------------
+ (join_test_pkey,t,t,t,t)
+(1 row)
+
+-- Test REINDEX CONCURRENTLY
+REINDEX INDEX CONCURRENTLY idx_join;
+SELECT show_index_status('idx_join');
+ show_index_status  
+--------------------
+ (idx_join,t,t,t,t)
+(1 row)
+
+ALTER INDEX idx_join INVISIBLE;
+SELECT show_index_status('idx_join');
+ show_index_status  
+--------------------
+ (idx_join,t,t,t,f)
+(1 row)
+
+REINDEX INDEX CONCURRENTLY idx_join;
+SELECT show_index_status('idx_join');
+ show_index_status  
+--------------------
+ (idx_join,t,t,t,f)
+(1 row)
+
+SELECT pg_get_indexdef('idx_join'::regclass);
+                                   pg_get_indexdef                                   
+-------------------------------------------------------------------------------------
+ CREATE INDEX idx_join ON schema_to_reindex.join_test USING btree (ref_id) INVISIBLE
+(1 row)
+
+ALTER INDEX idx_join VISIBLE;
+SELECT pg_get_indexdef('idx_join'::regclass);
+                              pg_get_indexdef                              
+---------------------------------------------------------------------------
+ CREATE INDEX idx_join ON schema_to_reindex.join_test USING btree (ref_id)
+(1 row)
+
+-- Test index visibility with indcheckxmin being true
+CREATE TABLE indcheckxmin_test(id int PRIMARY KEY);
+INSERT INTO indcheckxmin_test VALUES (1), (2), (3);
+CREATE INDEX CONCURRENTLY idx_checkxmin ON indcheckxmin_test(id);
+BEGIN;
+-- Simulate indcheckxmin being true
+UPDATE pg_index SET indcheckxmin = true WHERE indexrelid = 'idx_checkxmin'::regclass;
+ALTER INDEX idx_checkxmin INVISIBLE;  -- expect fail
+ERROR:  cannot update index visibility while indcheckxmin is true
+HINT:  Wait for all transactions that might see inconsistent HOT chains to complete
+ROLLBACK;
+-- Test prepared statements with index visibility
+CREATE TABLE prep_idx_test (id int, data text);
+CREATE INDEX prep_idx1 ON prep_idx_test(data);
+INSERT INTO prep_idx_test SELECT g, 'data ' || g FROM generate_series(1,100) g;
+-- Test with visible index
+PREPARE idx_plan AS SELECT * FROM prep_idx_test WHERE data = $1;
+EXPLAIN (COSTS OFF) EXECUTE idx_plan('data 1');
+                 QUERY PLAN                  
+---------------------------------------------
+ Bitmap Heap Scan on prep_idx_test
+   Recheck Cond: (data = 'data 1'::text)
+   ->  Bitmap Index Scan on prep_idx1
+         Index Cond: (data = 'data 1'::text)
+(4 rows)
+
+EXECUTE idx_plan('data 1');
+ id |  data  
+----+--------
+  1 | data 1
+(1 row)
+
+-- Test with invisible index
+ALTER INDEX prep_idx1 INVISIBLE;
+EXPLAIN (COSTS OFF) EXECUTE idx_plan('data 1');
+            QUERY PLAN             
+-----------------------------------
+ Seq Scan on prep_idx_test
+   Filter: (data = 'data 1'::text)
+(2 rows)
+
+EXECUTE idx_plan('data 1');
+ id |  data  
+----+--------
+  1 | data 1
+(1 row)
+
+-- Test with use_invisible_index
+SET use_invisible_index TO on;
+EXPLAIN (COSTS OFF) EXECUTE idx_plan('data 1');
+                 QUERY PLAN                  
+---------------------------------------------
+ Bitmap Heap Scan on prep_idx_test
+   Recheck Cond: (data = 'data 1'::text)
+   ->  Bitmap Index Scan on prep_idx1
+         Index Cond: (data = 'data 1'::text)
+(4 rows)
+
+EXECUTE idx_plan('data 1');
+ id |  data  
+----+--------
+  1 | data 1
+(1 row)
+
+SET use_invisible_index TO off;
+-- Assert plan cache is reset and index is not used
+EXPLAIN (COSTS OFF) EXECUTE idx_plan('data 1');
+            QUERY PLAN             
+-----------------------------------
+ Seq Scan on prep_idx_test
+   Filter: (data = 'data 1'::text)
+(2 rows)
+
+-- Make index visible and test again
+ALTER INDEX prep_idx1 VISIBLE;
+EXPLAIN (COSTS OFF) EXECUTE idx_plan('data 1');
+                 QUERY PLAN                  
+---------------------------------------------
+ Bitmap Heap Scan on prep_idx_test
+   Recheck Cond: (data = 'data 1'::text)
+   ->  Bitmap Index Scan on prep_idx1
+         Index Cond: (data = 'data 1'::text)
+(4 rows)
+
+EXECUTE idx_plan('data 1');
+ id |  data  
+----+--------
+  1 | data 1
+(1 row)
+
+-- Test index visibility with partitioned tables
+CREATE TABLE part_tbl(id int, data text) PARTITION BY RANGE(id);
+CREATE TABLE part1 PARTITION OF part_tbl FOR VALUES FROM (1) TO (100);
+CREATE TABLE part2 PARTITION OF part_tbl FOR VALUES FROM (100) TO (200);
+INSERT INTO part_tbl
+SELECT g, 'data ' || g
+FROM generate_series(1, 199) g;
+CREATE INDEX idx_part_tbl ON part_tbl(data);
+SELECT
+    c.relname AS index_name,
+    ct.relname AS table_name,
+    i.indisvisible
+FROM pg_index i
+JOIN pg_class c ON i.indexrelid = c.oid
+JOIN pg_class ct ON i.indrelid = ct.oid
+JOIN pg_inherits inh ON i.indrelid = inh.inhrelid
+WHERE inh.inhparent = 'part_tbl'::regclass::oid
+UNION ALL
+SELECT
+    c.relname AS index_name,
+    ct.relname AS table_name,
+    i.indisvisible
+FROM pg_index i
+JOIN pg_class c ON i.indexrelid = c.oid
+JOIN pg_class ct ON i.indrelid = ct.oid
+WHERE i.indrelid = 'part_tbl'::regclass::oid
+ORDER BY index_name;
+   index_name   | table_name | indisvisible 
+----------------+------------+--------------
+ idx_part_tbl   | part_tbl   | t
+ part1_data_idx | part1      | t
+ part2_data_idx | part2      | t
+(3 rows)
+
+-- Force use of indexes to avoid flaky test results
+SET enable_seqscan = off;
+EXPLAIN (COSTS OFF)
+SELECT * FROM part_tbl WHERE data = 'data 50';
+                        QUERY PLAN                         
+-----------------------------------------------------------
+ Append
+   ->  Index Scan using part1_data_idx on part1 part_tbl_1
+         Index Cond: (data = 'data 50'::text)
+   ->  Index Scan using part2_data_idx on part2 part_tbl_2
+         Index Cond: (data = 'data 50'::text)
+(5 rows)
+
+ALTER INDEX idx_part_tbl INVISIBLE;
+SELECT
+    c.relname AS index_name,
+    ct.relname AS table_name,
+    i.indisvisible
+FROM pg_index i
+JOIN pg_class c ON i.indexrelid = c.oid
+JOIN pg_class ct ON i.indrelid = ct.oid
+JOIN pg_inherits inh ON i.indrelid = inh.inhrelid
+WHERE inh.inhparent = 'part_tbl'::regclass::oid
+UNION ALL
+SELECT
+    c.relname AS index_name,
+    ct.relname AS table_name,
+    i.indisvisible
+FROM pg_index i
+JOIN pg_class c ON i.indexrelid = c.oid
+JOIN pg_class ct ON i.indrelid = ct.oid
+WHERE i.indrelid = 'part_tbl'::regclass::oid
+ORDER BY index_name;
+   index_name   | table_name | indisvisible 
+----------------+------------+--------------
+ idx_part_tbl   | part_tbl   | f
+ part1_data_idx | part1      | f
+ part2_data_idx | part2      | f
+(3 rows)
+
+-- Check query plan after setting invisible (should use seq scan)
+EXPLAIN (COSTS OFF)
+SELECT * FROM part_tbl WHERE data = 'data 50';
+                QUERY PLAN                
+------------------------------------------
+ Append
+   ->  Seq Scan on part1 part_tbl_1
+         Disabled: true
+         Filter: (data = 'data 50'::text)
+   ->  Seq Scan on part2 part_tbl_2
+         Disabled: true
+         Filter: (data = 'data 50'::text)
+(7 rows)
+
+SET use_invisible_index TO on;
+EXPLAIN (COSTS OFF)
+SELECT * FROM part_tbl WHERE data = 'data 50';
+                        QUERY PLAN                         
+-----------------------------------------------------------
+ Append
+   ->  Index Scan using part1_data_idx on part1 part_tbl_1
+         Index Cond: (data = 'data 50'::text)
+   ->  Index Scan using part2_data_idx on part2 part_tbl_2
+         Index Cond: (data = 'data 50'::text)
+(5 rows)
+
+SET use_invisible_index TO off;
+EXPLAIN (COSTS OFF)
+SELECT * FROM part_tbl WHERE data = 'data 50';
+                QUERY PLAN                
+------------------------------------------
+ Append
+   ->  Seq Scan on part1 part_tbl_1
+         Disabled: true
+         Filter: (data = 'data 50'::text)
+   ->  Seq Scan on part2 part_tbl_2
+         Disabled: true
+         Filter: (data = 'data 50'::text)
+(7 rows)
+
+ALTER INDEX idx_part_tbl VISIBLE;
+SELECT c.relname, i.indisvisible
+FROM pg_index i
+JOIN pg_class c ON i.indexrelid = c.oid
+WHERE c.relname LIKE 'idx_part_tbl%'
+ORDER BY c.relname;
+   relname    | indisvisible 
+--------------+--------------
+ idx_part_tbl | t
+(1 row)
+
+EXPLAIN (COSTS OFF)
+SELECT * FROM part_tbl WHERE data = 'data 50';
+                        QUERY PLAN                         
+-----------------------------------------------------------
+ Append
+   ->  Index Scan using part1_data_idx on part1 part_tbl_1
+         Index Cond: (data = 'data 50'::text)
+   ->  Index Scan using part2_data_idx on part2 part_tbl_2
+         Index Cond: (data = 'data 50'::text)
+(5 rows)
+
+SET enable_seqscan = on;
+-- Test REINDEX maintains visibility setting
+ALTER INDEX idx_part_tbl INVISIBLE;
+REINDEX INDEX idx_part_tbl;
+SELECT c.relname, i.indisvisible
+FROM pg_index i
+JOIN pg_class c ON i.indexrelid = c.oid
+WHERE c.relname LIKE 'idx_part_tbl%'
+ORDER BY c.relname;
+   relname    | indisvisible 
+--------------+--------------
+ idx_part_tbl | f
+(1 row)
+
+-- Test that index visibility is preserved after ALTER TABLE
+CREATE TABLE vis_test(id INT PRIMARY KEY, data text);
+\d vis_test
+        Table "schema_to_reindex.vis_test"
+ Column |  Type   | Collation | Nullable | Default 
+--------+---------+-----------+----------+---------
+ id     | integer |           | not null | 
+ data   | text    |           |          | 
+Indexes:
+    "vis_test_pkey" PRIMARY KEY, btree (id)
+
+ALTER INDEX vis_test_pkey INVISIBLE;
+\d vis_test
+        Table "schema_to_reindex.vis_test"
+ Column |  Type   | Collation | Nullable | Default 
+--------+---------+-----------+----------+---------
+ id     | integer |           | not null | 
+ data   | text    |           |          | 
+Indexes:
+    "vis_test_pkey" PRIMARY KEY, btree (id) INVISIBLE
+
+ALTER TABLE vis_test ALTER COLUMN id SET DATA TYPE bigint;
+\d vis_test
+        Table "schema_to_reindex.vis_test"
+ Column |  Type  | Collation | Nullable | Default 
+--------+--------+-----------+----------+---------
+ id     | bigint |           | not null | 
+ data   | text   |           |          | 
+Indexes:
+    "vis_test_pkey" PRIMARY KEY, btree (id) INVISIBLE
+
+ALTER TABLE vis_test ALTER COLUMN id SET DATA TYPE int;
+\d vis_test
+        Table "schema_to_reindex.vis_test"
+ Column |  Type   | Collation | Nullable | Default 
+--------+---------+-----------+----------+---------
+ id     | integer |           | not null | 
+ data   | text    |           |          | 
+Indexes:
+    "vis_test_pkey" PRIMARY KEY, btree (id) INVISIBLE
+
+ALTER INDEX vis_test_pkey VISIBLE;
+\d vis_test
+        Table "schema_to_reindex.vis_test"
+ Column |  Type   | Collation | Nullable | Default 
+--------+---------+-----------+----------+---------
+ id     | integer |           | not null | 
+ data   | text    |           |          | 
+Indexes:
+    "vis_test_pkey" PRIMARY KEY, btree (id)
+
+-- Test CREATE INDEX with INVISIBLE option
+CREATE TABLE invis_test(id int, data text);
+INSERT INTO invis_test SELECT g, 'data ' || g FROM generate_series(1,100) g;
+CREATE INDEX idx_invis1 ON invis_test(data) INVISIBLE;
+\d invis_test
+       Table "schema_to_reindex.invis_test"
+ Column |  Type   | Collation | Nullable | Default 
+--------+---------+-----------+----------+---------
+ id     | integer |           |          | 
+ data   | text    |           |          | 
+Indexes:
+    "idx_invis1" btree (data) INVISIBLE
+
+\d idx_invis1
+Index "schema_to_reindex.idx_invis1"
+ Column | Type | Key? | Definition 
+--------+------+------+------------
+ data   | text | yes  | data
+btree, for table "schema_to_reindex.invis_test", invisible
+
+ALTER INDEX idx_invis1 VISIBLE;
+\d invis_test
+       Table "schema_to_reindex.invis_test"
+ Column |  Type   | Collation | Nullable | Default 
+--------+---------+-----------+----------+---------
+ id     | integer |           |          | 
+ data   | text    |           |          | 
+Indexes:
+    "idx_invis1" btree (data)
+
+\d idx_invis1
+Index "schema_to_reindex.idx_invis1"
+ Column | Type | Key? | Definition 
+--------+------+------+------------
+ data   | text | yes  | data
+btree, for table "schema_to_reindex.invis_test"
+
+-- Clean up
+DROP TABLE index_test;
+DROP TABLE join_test;
+DROP FUNCTION get_data_length;
+DROP FUNCTION show_index_status;
+DROP TABLE indcheckxmin_test CASCADE;
+DEALLOCATE idx_plan;
+DROP TABLE prep_idx_test;
+DROP TABLE part_tbl CASCADE;
+DROP TABLE vis_test;
+DROP TABLE invis_test;
 -- Failure for unauthorized user
 CREATE ROLE regress_reindexuser NOLOGIN;
 SET SESSION ROLE regress_reindexuser;
diff --git a/src/test/regress/sql/create_index.sql b/src/test/regress/sql/create_index.sql
index e21ff42651..7b6fe83390 100644
--- a/src/test/regress/sql/create_index.sql
+++ b/src/test/regress/sql/create_index.sql
@@ -1496,6 +1496,355 @@ END;
 -- concurrently
 REINDEX SCHEMA CONCURRENTLY schema_to_reindex;
 
+-- Test index visibility functionality
+
+CREATE TABLE index_test(
+    id INT PRIMARY KEY,
+    data TEXT,
+    num INT,
+    vector INT[],
+    range INT4RANGE
+);
+
+INSERT INTO index_test
+SELECT
+    g,
+    'data ' || g,
+    g % 100,
+    ARRAY[g, g+1, g+2],
+    int4range(g, g+10)
+FROM generate_series(1, 1000) g;
+
+-- Function for testing
+CREATE FUNCTION get_data_length(text) RETURNS INT AS $$
+    SELECT length($1);
+$$ LANGUAGE SQL IMMUTABLE;
+
+-- Helper function to show index status
+CREATE OR REPLACE FUNCTION show_index_status(index_name text)
+RETURNS TABLE (
+    indexrelid regclass,
+    indisvalid boolean,
+    indisready boolean,
+    indislive boolean,
+    indisvisible boolean
+) AS $$
+BEGIN
+    RETURN QUERY EXECUTE format('
+        SELECT indexrelid::regclass, indisvalid, indisready, indislive, indisvisible
+        FROM pg_index
+        WHERE indexrelid = %L::regclass', index_name);
+END;
+$$ LANGUAGE plpgsql;
+
+-- Create and test each index type
+-- 1. Basic single-column index
+CREATE INDEX idx_single ON index_test(data);
+SELECT show_index_status('idx_single');
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE data = 'data 500';
+ALTER INDEX idx_single INVISIBLE;
+SELECT show_index_status('idx_single');
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE data = 'data 500';
+ALTER INDEX idx_single VISIBLE;
+SELECT show_index_status('idx_single');
+
+-- 2. Multi-column index
+CREATE INDEX idx_multi ON index_test(num, data);
+SELECT show_index_status('idx_multi');
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE num = 50 AND data > 'data 500';
+ALTER INDEX idx_multi INVISIBLE;
+SELECT show_index_status('idx_multi');
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE num = 50 AND data > 'data 500';
+ALTER INDEX idx_multi VISIBLE;
+SELECT show_index_status('idx_multi');
+
+-- 3. Partial index
+CREATE INDEX idx_partial ON index_test(num) WHERE num < 50;
+SELECT show_index_status('idx_partial');
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE num = 25;
+ALTER INDEX idx_partial INVISIBLE;
+SELECT show_index_status('idx_partial');
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE num = 25;
+ALTER INDEX idx_partial VISIBLE;
+SELECT show_index_status('idx_partial');
+
+-- 4. Expression index
+CREATE INDEX idx_expression ON index_test((lower(data)));
+SELECT show_index_status('idx_expression');
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE lower(data) = 'data 500';
+ALTER INDEX idx_expression INVISIBLE;
+SELECT show_index_status('idx_expression');
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE lower(data) = 'data 500';
+ALTER INDEX idx_expression VISIBLE;
+SELECT show_index_status('idx_expression');
+
+-- 5. GIN index
+CREATE INDEX idx_gin ON index_test USING gin(vector);
+SELECT show_index_status('idx_gin');
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE vector @> ARRAY[500];
+ALTER INDEX idx_gin INVISIBLE;
+SELECT show_index_status('idx_gin');
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE vector @> ARRAY[500];
+ALTER INDEX idx_gin VISIBLE;
+SELECT show_index_status('idx_gin');
+
+-- 6. GiST index
+CREATE INDEX idx_gist ON index_test USING gist(range);
+SELECT show_index_status('idx_gist');
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE range && int4range(100, 110);
+ALTER INDEX idx_gist INVISIBLE;
+SELECT show_index_status('idx_gist');
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE range && int4range(100, 110);
+ALTER INDEX idx_gist VISIBLE;
+SELECT show_index_status('idx_gist');
+
+-- 7. Covering index
+CREATE INDEX idx_covering ON index_test(num) INCLUDE (data);
+SELECT show_index_status('idx_covering');
+EXPLAIN (COSTS OFF) SELECT num, data FROM index_test WHERE num = 50;
+ALTER INDEX idx_covering INVISIBLE;
+SELECT show_index_status('idx_covering');
+EXPLAIN (COSTS OFF) SELECT num, data FROM index_test WHERE num = 50;
+ALTER INDEX idx_covering VISIBLE;
+SELECT show_index_status('idx_covering');
+
+-- 8. Unique index
+CREATE UNIQUE INDEX idx_unique ON index_test(id, data);
+SELECT show_index_status('idx_unique');
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE id = 500 AND data = 'data 500';
+ALTER INDEX idx_unique INVISIBLE;
+SELECT show_index_status('idx_unique');
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE id = 500 AND data = 'data 500';
+ALTER INDEX idx_unique VISIBLE;
+SELECT show_index_status('idx_unique');
+
+-- 9. Function-based index
+CREATE INDEX idx_func ON index_test(get_data_length(data));
+SELECT show_index_status('idx_func');
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE get_data_length(data) = 10;
+ALTER INDEX idx_func INVISIBLE;
+SELECT show_index_status('idx_func');
+EXPLAIN (COSTS OFF) SELECT * FROM index_test WHERE get_data_length(data) = 10;
+ALTER INDEX idx_func VISIBLE;
+SELECT show_index_status('idx_func');
+
+-- 10. Join index
+CREATE TABLE join_test (id INT PRIMARY KEY, ref_id INT);
+INSERT INTO join_test SELECT g, g % 100 FROM generate_series(1, 1000) g;
+CREATE INDEX idx_join ON join_test(ref_id);
+SELECT show_index_status('idx_join');
+
+EXPLAIN (COSTS OFF)
+SELECT jt.id, it.data
+FROM join_test jt
+JOIN index_test it ON jt.ref_id = it.num
+WHERE jt.id BETWEEN 100 AND 200;
+
+-- Set all indexes to invisible to force seq scan
+ALTER INDEX idx_join INVISIBLE;
+ALTER INDEX join_test_pkey INVISIBLE;
+SELECT show_index_status('idx_join');
+SELECT show_index_status('join_test_pkey');
+
+EXPLAIN (COSTS OFF)
+SELECT jt.id, it.data
+FROM join_test jt
+JOIN index_test it ON jt.ref_id = it.num
+WHERE jt.id BETWEEN 100 AND 200;
+
+ALTER INDEX idx_join VISIBLE;
+ALTER INDEX join_test_pkey VISIBLE;
+SELECT show_index_status('idx_join');
+SELECT show_index_status('join_test_pkey');
+
+-- Test REINDEX CONCURRENTLY
+REINDEX INDEX CONCURRENTLY idx_join;
+SELECT show_index_status('idx_join');
+
+ALTER INDEX idx_join INVISIBLE;
+SELECT show_index_status('idx_join');
+REINDEX INDEX CONCURRENTLY idx_join;
+SELECT show_index_status('idx_join');
+
+SELECT pg_get_indexdef('idx_join'::regclass);
+ALTER INDEX idx_join VISIBLE;
+SELECT pg_get_indexdef('idx_join'::regclass);
+
+-- Test index visibility with indcheckxmin being true
+
+CREATE TABLE indcheckxmin_test(id int PRIMARY KEY);
+INSERT INTO indcheckxmin_test VALUES (1), (2), (3);
+CREATE INDEX CONCURRENTLY idx_checkxmin ON indcheckxmin_test(id);
+BEGIN;
+-- Simulate indcheckxmin being true
+UPDATE pg_index SET indcheckxmin = true WHERE indexrelid = 'idx_checkxmin'::regclass;
+ALTER INDEX idx_checkxmin INVISIBLE;  -- expect fail
+ROLLBACK;
+
+-- Test prepared statements with index visibility
+CREATE TABLE prep_idx_test (id int, data text);
+CREATE INDEX prep_idx1 ON prep_idx_test(data);
+INSERT INTO prep_idx_test SELECT g, 'data ' || g FROM generate_series(1,100) g;
+
+-- Test with visible index
+PREPARE idx_plan AS SELECT * FROM prep_idx_test WHERE data = $1;
+EXPLAIN (COSTS OFF) EXECUTE idx_plan('data 1');
+EXECUTE idx_plan('data 1');
+
+-- Test with invisible index
+ALTER INDEX prep_idx1 INVISIBLE;
+EXPLAIN (COSTS OFF) EXECUTE idx_plan('data 1');
+EXECUTE idx_plan('data 1');
+
+-- Test with use_invisible_index
+SET use_invisible_index TO on;
+EXPLAIN (COSTS OFF) EXECUTE idx_plan('data 1');
+EXECUTE idx_plan('data 1');
+SET use_invisible_index TO off;
+-- Assert plan cache is reset and index is not used
+EXPLAIN (COSTS OFF) EXECUTE idx_plan('data 1');
+
+-- Make index visible and test again
+ALTER INDEX prep_idx1 VISIBLE;
+EXPLAIN (COSTS OFF) EXECUTE idx_plan('data 1');
+EXECUTE idx_plan('data 1');
+
+-- Test index visibility with partitioned tables
+CREATE TABLE part_tbl(id int, data text) PARTITION BY RANGE(id);
+CREATE TABLE part1 PARTITION OF part_tbl FOR VALUES FROM (1) TO (100);
+CREATE TABLE part2 PARTITION OF part_tbl FOR VALUES FROM (100) TO (200);
+
+INSERT INTO part_tbl
+SELECT g, 'data ' || g
+FROM generate_series(1, 199) g;
+
+CREATE INDEX idx_part_tbl ON part_tbl(data);
+
+SELECT
+    c.relname AS index_name,
+    ct.relname AS table_name,
+    i.indisvisible
+FROM pg_index i
+JOIN pg_class c ON i.indexrelid = c.oid
+JOIN pg_class ct ON i.indrelid = ct.oid
+JOIN pg_inherits inh ON i.indrelid = inh.inhrelid
+WHERE inh.inhparent = 'part_tbl'::regclass::oid
+UNION ALL
+SELECT
+    c.relname AS index_name,
+    ct.relname AS table_name,
+    i.indisvisible
+FROM pg_index i
+JOIN pg_class c ON i.indexrelid = c.oid
+JOIN pg_class ct ON i.indrelid = ct.oid
+WHERE i.indrelid = 'part_tbl'::regclass::oid
+ORDER BY index_name;
+
+-- Force use of indexes to avoid flaky test results
+SET enable_seqscan = off;
+
+EXPLAIN (COSTS OFF)
+SELECT * FROM part_tbl WHERE data = 'data 50';
+
+ALTER INDEX idx_part_tbl INVISIBLE;
+
+SELECT
+    c.relname AS index_name,
+    ct.relname AS table_name,
+    i.indisvisible
+FROM pg_index i
+JOIN pg_class c ON i.indexrelid = c.oid
+JOIN pg_class ct ON i.indrelid = ct.oid
+JOIN pg_inherits inh ON i.indrelid = inh.inhrelid
+WHERE inh.inhparent = 'part_tbl'::regclass::oid
+UNION ALL
+SELECT
+    c.relname AS index_name,
+    ct.relname AS table_name,
+    i.indisvisible
+FROM pg_index i
+JOIN pg_class c ON i.indexrelid = c.oid
+JOIN pg_class ct ON i.indrelid = ct.oid
+WHERE i.indrelid = 'part_tbl'::regclass::oid
+ORDER BY index_name;
+
+-- Check query plan after setting invisible (should use seq scan)
+EXPLAIN (COSTS OFF)
+SELECT * FROM part_tbl WHERE data = 'data 50';
+
+SET use_invisible_index TO on;
+
+EXPLAIN (COSTS OFF)
+SELECT * FROM part_tbl WHERE data = 'data 50';
+
+SET use_invisible_index TO off;
+
+EXPLAIN (COSTS OFF)
+SELECT * FROM part_tbl WHERE data = 'data 50';
+
+ALTER INDEX idx_part_tbl VISIBLE;
+
+SELECT c.relname, i.indisvisible
+FROM pg_index i
+JOIN pg_class c ON i.indexrelid = c.oid
+WHERE c.relname LIKE 'idx_part_tbl%'
+ORDER BY c.relname;
+
+EXPLAIN (COSTS OFF)
+SELECT * FROM part_tbl WHERE data = 'data 50';
+
+SET enable_seqscan = on;
+
+-- Test REINDEX maintains visibility setting
+ALTER INDEX idx_part_tbl INVISIBLE;
+REINDEX INDEX idx_part_tbl;
+
+SELECT c.relname, i.indisvisible
+FROM pg_index i
+JOIN pg_class c ON i.indexrelid = c.oid
+WHERE c.relname LIKE 'idx_part_tbl%'
+ORDER BY c.relname;
+
+-- Test that index visibility is preserved after ALTER TABLE
+CREATE TABLE vis_test(id INT PRIMARY KEY, data text);
+\d vis_test
+
+ALTER INDEX vis_test_pkey INVISIBLE;
+\d vis_test
+
+ALTER TABLE vis_test ALTER COLUMN id SET DATA TYPE bigint;
+\d vis_test
+
+ALTER TABLE vis_test ALTER COLUMN id SET DATA TYPE int;
+\d vis_test
+
+ALTER INDEX vis_test_pkey VISIBLE;
+\d vis_test
+
+-- Test CREATE INDEX with INVISIBLE option
+CREATE TABLE invis_test(id int, data text);
+INSERT INTO invis_test SELECT g, 'data ' || g FROM generate_series(1,100) g;
+
+CREATE INDEX idx_invis1 ON invis_test(data) INVISIBLE;
+\d invis_test
+\d idx_invis1
+
+ALTER INDEX idx_invis1 VISIBLE;
+\d invis_test
+\d idx_invis1
+
+-- Clean up
+DROP TABLE index_test;
+DROP TABLE join_test;
+DROP FUNCTION get_data_length;
+DROP FUNCTION show_index_status;
+DROP TABLE indcheckxmin_test CASCADE;
+DEALLOCATE idx_plan;
+DROP TABLE prep_idx_test;
+DROP TABLE part_tbl CASCADE;
+DROP TABLE vis_test;
+DROP TABLE invis_test;
+
 -- Failure for unauthorized user
 CREATE ROLE regress_reindexuser NOLOGIN;
 SET SESSION ROLE regress_reindexuser;
-- 
2.39.5 (Apple Git-154)

#90Robert Treat
rob@xzilla.net
In reply to: Shayon Mukherjee (#89)
Re: [PATCH] Re: Proposal to Enable/Disable Index using ALTER INDEX

On Mon, Apr 28, 2025 at 7:23 AM Shayon Mukherjee <shayonj@gmail.com> wrote:

On Thu, Apr 24, 2025 at 12:45 AM jian he <jian.universality@gmail.com> wrote:

Thank you for the feedback. I have also updated the feedback from [1] as well. Few extra notes:

- Attached v18
- Rebased against master
- Updated the commit message
- Updated the target remote version to now be fout->remoteVersion >= 190000
- Using a UNION ALL query to show all indexes from part_tbl partitioned tables in the specs as noted in [1]. The query suggested in [1] wasn't encompassing all the indexes, hence the UNION ALL for WHERE i.indrelid = 'part_tbl'::regclass::oid.

Having looked at this patch, I'm a bit surprised that it would be
considered for commit; not that the work hasn't been done with rigor,
but the implementation seems extremely obtuse for the common use cases
that have been envisioned.

As a primary example, imagine you have 2 indexes and you want to test
if one index can handle the load via skip scans. With this feature, in
order to do that SAFELY, you would need to first figure out how to
ensure that the `force_invisible_index` GUC has been set to true
across all possible backends, even though there seems like a general
agreement that there isn't an easy way to do this (see comments around
cached plans), and to make it more complicated, this needs to occur
across all downstream replicas. Only then would it be safe to run the
alter index to set your index invisible, at which point you could then
test at the query/session level to determine which queries will be
supportable without the risk of having your server(s) tank due to
overload when you start getting hundreds of queries who plan has gone
sideways. Ideally you would be able to do this in the opposite
fashion; start with a session level guc that allows you to test in a
controlled manner, and then if that works you start to roll that out
across multiple sessions, and then to multiple servers, before
eventually dropping the index.

But that isn't the only gap; imagine if you want to test across 3 or
more indexes; with this implementation, the "use invisible" flag is
all or nothing, which again makes it difficult to work with;
especially if you have multiple cases within the system that might
make use of this feature (and people will surely run invisible indexes
for weeks in production to ensure some random monthly report doesn't
come along and cause trouble). I'm also skeptical of the idea that
users need a way to add invisible indexes they can then test to see if
they are useful because 1) this is basically how indexes already work,
meaning if you add an index and it isn't useful, it doesn't get used,
and 2) we have an extension (hypopg) which arguably provides this
functionality without causing a bunch of i/o, and there isn't nearly
the clamor to add this functionality in to core as there is for having
a way to "soft drop" indexes. TBH, with this implementation, I can see
people running with all indexes set invisible and
force_invisible_index set to true, just to enable simple granular
control when they need it.

I know this thread is rather old and there doesn't seem to be full
agreement on the ALTER vs GUC implementation idea, and even though I
agree with the sentiment that the GUC system is little more than the
"half-baked take on planner hints", the upside of GUC first
implementations is that they tend to provide better usability than
most grammer related implementations. Consider that any implementation
which requires the use of ALTER statements (which this one does)
undercuts its own usefulness because it adds significant operational
risk in any attempt to use it just by the nature of ALTER leading to
system-wide (including multi-server) changes, and while it feels like
we often dismiss operational risk, those are exactly the folks who
need this feature the most.

P.S. I really do want to thank Shayon for sticking with this; I
thought about saying that up front but it felt cliche, but I do think
it is important to say it.

Robert Treat
https://xzilla.net

#91David Rowley
dgrowleyml@gmail.com
In reply to: Robert Treat (#90)
Re: [PATCH] Re: Proposal to Enable/Disable Index using ALTER INDEX

On Fri, 6 Jun 2025 at 08:14, Robert Treat <rob@xzilla.net> wrote:

I know this thread is rather old and there doesn't seem to be full
agreement on the ALTER vs GUC implementation idea, and even though I
agree with the sentiment that the GUC system is little more than the
"half-baked take on planner hints", the upside of GUC first
implementations is that they tend to provide better usability than
most grammer related implementations. Consider that any implementation
which requires the use of ALTER statements (which this one does)
undercuts its own usefulness because it adds significant operational
risk in any attempt to use it just by the nature of ALTER leading to
system-wide (including multi-server) changes, and while it feels like
we often dismiss operational risk, those are exactly the folks who
need this feature the most.

Thanks for weighing in.

In my mind, this feature is for "I'm almost 100% certain this index
isn't needed, I want to make sure I'm 100% right in a way that I can
quickly fix the ensuing chaos if I'm wrong". It sounds like in your
mind it's "I want to run some experiments to see if this index is
needed or not". I think both have merit, but I think the former gets
you closer to 100% certainty, as it'll be replicated to physical
replica servers.

I'd personally be looking at something like pg_stat_all_indexes
instead of playing around with session-level GUC setting to figure out
if an index was being used or not and I'd be looking to the ALTER
TABLE once I'd seen nothing changing in pg_stat_all_indexes for some
time period. I mean, what am I really going to do in session-level
GUC? -- Run all possible queries that the application runs and check
they're still fast? If I could do that, then I could equally just not
use the GUC and look at EXPLAIN on all those queries to see if the
index is picked anywhere.

Maybe we need to hear from a few more people who have recently faced
the dilemma of removing a seemingly unused index on a critical
application.

For me, I have been in this situation before. The database wasn't
massive. I could likely have put the index back in 10 mins or so.
However, it'd still have been nice to have something else to try
before trying DROP INDEX. It's quite easy to imagine your finger
hovering over the [Enter] key for a while before typing that statement
when the index is large.

P.S. I really do want to thank Shayon for sticking with this;

+1

David

#92Sami Imseih
samimseih@gmail.com
In reply to: David Rowley (#91)
Re: [PATCH] Re: Proposal to Enable/Disable Index using ALTER INDEX

Thanks for weighing in.

+1

In my mind, this feature is for "I'm almost 100% certain this index
isn't needed, I want to make sure I'm 100% right in a way that I can
quickly fix the ensuing chaos if I'm wrong".

This is the primary use-case. A user performs an ALTER INDEX...
INVISIBLE, and they monitor the workload and pg_stat_all_indexes
( on primary and hot standbys ) until they feel confident enough
to fully commit to dropping the index. This is the case that many
users out there want. The bonus is the locking acquired to flip
the VISIBLE/INVISIBLE flag is a ShareUpdateExclusiveLock
on the index, so this operation can only be blocked by VACUUM
or other ALTERs, etc,

I'm also skeptical of the idea that
users need a way to add invisible indexes they can then test to see if
they are useful because 1) this is basically how indexes already work,
meaning if you add an index and it isn't useful, it doesn't get used,

The GUC will be useful for experimentation or for the safer rollout of
new indexes. For example, an index can be created as INVISIBLE initially,
and with use_invisible_index, one can observe how the index may impact
various queries before fully committing to enabling it. Also, if we allow an
index to be INVISIBLE initially, we need to provide the user with this
GUC; otherwise, I can’t see why a user would want to make an
index INVISIBLE initially.

and 2) we have an extension (hypopg) which arguably provides this
functionality without causing a bunch of i/o, and there isn't nearly
the clamor to add this functionality in to core as there is for having
a way to "soft drop" indexes.

I have not worked much with HypoPG, but from what I understand,
it works only at the EXPLAIN level. It is purely an experimentation tool.
However, the proposed GUC can also be used in more places,
including, pg_hint_plan ( at least with the SET hint without any changes
to pg_hint_plan).

P.S. I really do want to thank Shayon for sticking with this;

+1

+1

--
Sami Imseih
Amazon Web Services (AWS)

#93Robert Treat
rob@xzilla.net
In reply to: Sami Imseih (#92)
Re: [PATCH] Re: Proposal to Enable/Disable Index using ALTER INDEX

On Thu, Jun 5, 2025 at 8:16 PM Sami Imseih <samimseih@gmail.com> wrote:

Thanks for weighing in.

+1

In my mind, this feature is for "I'm almost 100% certain this index
isn't needed, I want to make sure I'm 100% right in a way that I can
quickly fix the ensuing chaos if I'm wrong".

This is the primary use-case. A user performs an ALTER INDEX...
INVISIBLE, and they monitor the workload and pg_stat_all_indexes
( on primary and hot standbys ) until they feel confident enough
to fully commit to dropping the index. This is the case that many
users out there want.

To be blunt, the users who think they want this either aren't trying to
solve the actual hard problem, or they haven't thought about how this
operation needs to happen that deeply. Don't get me wrong, it would be an
improvement to have some type of mechanism that can move you from almost
100% to 100%, but the real problem is how do you SAFELY get to almost 100%
in the first place? You need to be able to build that confidence through
smaller incremental changes to your production workload, and ALTER INDEX
won't help you with that. In production, you aren't watching to see what
happen with pg_stat_all_indexes, because you will first be watching
pg_stat_activity to see if the plans have flipped in some way that leads to
an overloaded server (extra latency, poor caching effects, extra buffers
usage, etc). And the replicated bit? Sadly someone launched some big DML
operation so you're waiting for that to finish so the "quick rollback" can
actually get to those other servers.

I'm also skeptical of the idea that
users need a way to add invisible indexes they can then test to see if
they are useful because 1) this is basically how indexes already work,
meaning if you add an index and it isn't useful, it doesn't get used,

The GUC will be useful for experimentation or for the safer rollout of
new indexes. For example, an index can be created as INVISIBLE initially,
and with use_invisible_index, one can observe how the index may impact
various queries before fully committing to enabling it. Also, if we allow
an
index to be INVISIBLE initially, we need to provide the user with this
GUC; otherwise, I can’t see why a user would want to make an
index INVISIBLE initially.

Again, I can squint enough to see the use case, but the risk with indexes
is FAR greater in their removal rather than in adding new ones; and to
whatever degree you think slow rolling out the generally not dangerous
addition of new indexes is, it's an argument that should really speak to
how much more important the ability to slow roll index removal is.

and 2) we have an extension (hypopg) which arguably provides this
functionality without causing a bunch of i/o, and there isn't nearly
the clamor to add this functionality in to core as there is for having
a way to "soft drop" indexes.

I have not worked much with HypoPG, but from what I understand,
it works only at the EXPLAIN level. It is purely an experimentation tool.
However, the proposed GUC can also be used in more places,
including, pg_hint_plan ( at least with the SET hint without any changes
to pg_hint_plan).

To be clear, the reason I bring up hypopg is that if slow rolling the
addition of indexes was a significant customer problem, we'd have people
clamoring for better tools to do it, and by and large we don't, and I posit
that by and large that's because adding new indexes is not really that
dangerous.

I'm not saying there isn't any possible use case that could be solved with
the above (although mind my example of people running with all indexes and
the guc always enabled; I don't think thats a sceanrio that anyone thinks
should be recommended, but it will be a far more common use case given this
design; and btw it wont work well with pg_hint_plan because the GUC/ALTER
combo doesn't play well with multiple indexes), but more importantly, if we
only solve the simple cases at the expense of the hard problem, we're doing
our users a disservice.

Robert Treat
https://xzilla.net

#94David G. Johnston
david.g.johnston@gmail.com
In reply to: Robert Treat (#93)
Re: [PATCH] Re: Proposal to Enable/Disable Index using ALTER INDEX

On Thu, Jun 5, 2025 at 7:32 PM Robert Treat <rob@xzilla.net> wrote:

I'm not saying there isn't any possible use case that could be solved with
the above (although mind my example of people running with all indexes and
the guc always enabled; I don't think thats a sceanrio that anyone thinks
should be recommended, but it will be a far more common use case given this
design; and btw it wont work well with pg_hint_plan because the GUC/ALTER
combo doesn't play well with multiple indexes), but more importantly, if we
only solve the simple cases at the expense of the hard problem, we're doing
our users a disservice.

So, as proposed:

Replicate-able DDL: Enables a holistic picture but is a foot-gun for the
DBA in the "revert" case.

Boolean GUC: Enables some experimentation; can be used to quickly re-enable
invisible indexes that are waiting for the DDL to make them visible again.
Insufficiently granular for quickly exploring various options.

The granularity issue seems overcome-able:

Multi-Valued GUC: Specify explicitly which invisible indexes to make
visible, eliminating the granularity problem of the boolean option. Can
provide a "pg_catalog.pg_all_indexes" magic value impossible to exist in
reality that would enable the "true" boolean option - false would just be
an empty setting.

The foot-gun seems safe enough to offer given the benefit the feature
provides.

Even without the GUC the proposed feature seems an improvement over the
status quo. The boolean I'd probably leave on the table; while a bit ugly
in usage for the expected experimentation the multi-valued text GUC seems
reasonable (and will effectively prohibit relying on invisible indexes
generally).

Are there other alternative designs this last bit of discussion is meant to
promote or are people actively voting for the status quo over the addition
of the index visibility attribute? Or, maybe more properly, is index
replication the dividing line here and any new feature has to make that
aspect optional?

If we are going to bite on the multi-valued text GUC it could just define
which indexes to ignore when planning and we'd have the local-only feature
done. Which leads then to just implementing this feature (with
multi-valued GUC) as the option by which the DBA can choose to apply their
local GUC changes across their secondaries without having to (but can if
they wish) apply the GUC change to all those machines as well.

David J.

#95Sami Imseih
samimseih@gmail.com
In reply to: David G. Johnston (#94)
Re: [PATCH] Re: Proposal to Enable/Disable Index using ALTER INDEX

Don't get me wrong, it would be an improvement to have some type of
mechanism that can move you from almost 100% to 100%, but the real
problem is how do you SAFELY get to almost 100% in the first place?

This big use case is precisely the "almost 100% to 100%" confidence problem.
Usually, users have done their homework, they've analyzed
workloads, tuned queries and maybe created a better index. Now, they see some
indexes that are unused or underused. In the current state, the only
option is to drop the
index. But if that turns out to be a mistake, they have to rebuild it, which
can be slow and disruptive. With this feature, If making the index
invisible causes
problems, they can quickly make it visible again without needing to
rebuild anything.

Also, users coming from other databases, both commercial and open source, are
already used to this kind of setup: an ALTER command for visibility, plus a
parameter to control whether invisible indexes are used on a per session level.
So we're not inventing something new here; we're following a well-known and
useful pattern that makes life easier, especially for users migrating to
Postgres.

I am still trying to understand. Do you think the ALTER command is not useful?
or, do you think the GUC is all we need and it should be more granular?
or maybe something different?

--
Sami

#96David Rowley
dgrowleyml@gmail.com
In reply to: Robert Treat (#93)
Re: [PATCH] Re: Proposal to Enable/Disable Index using ALTER INDEX

On Fri, 6 Jun 2025 at 14:32, Robert Treat <rob@xzilla.net> wrote:

In production, you aren't watching to see what happen with pg_stat_all_indexes, because you will first be watching pg_stat_activity to see if the plans have flipped in some way that leads to an overloaded server (extra latency, poor caching effects, extra buffers usage, etc). And the replicated bit? Sadly someone launched some big DML operation so you're waiting for that to finish so the "quick rollback" can actually get to those other servers.

I think you've misunderstood when you'd be looking at
pg_stat_all_indexes. The time when you'd want to look at
pg_stat_all_indexes is *before* you DROP INDEX and before you ALTER
TABLE INVISIBLE the index. What you'd likely want to look for there
are indexes that have the last_idx_scan set to something far in the
past or set to NULL.

I'm curious to know if you've ever had to drop an index out of
production before? What did you think about when you'd just typed the
DROP INDEX command and were contemplating your future? How long did
you pause before pressing [Enter]?

Can you list your proposed series of steps you'd recommend to a DBA
wishing to remove an index, assuming this feature exists in core as
you'd like it to?

David

#97Robert Treat
rob@xzilla.net
In reply to: David Rowley (#96)
Re: [PATCH] Re: Proposal to Enable/Disable Index using ALTER INDEX

On Fri, Jun 6, 2025 at 8:04 PM David Rowley <dgrowleyml@gmail.com> wrote:

On Fri, 6 Jun 2025 at 14:32, Robert Treat <rob@xzilla.net> wrote:

In production, you aren't watching to see what happen with pg_stat_all_indexes, because you will first be watching pg_stat_activity to see if the plans have flipped in some way that leads to an overloaded server (extra latency, poor caching effects, extra buffers usage, etc). And the replicated bit? Sadly someone launched some big DML operation so you're waiting for that to finish so the "quick rollback" can actually get to those other servers.

I think you've misunderstood when you'd be looking at
pg_stat_all_indexes. The time when you'd want to look at
pg_stat_all_indexes is *before* you DROP INDEX and before you ALTER
TABLE INVISIBLE the index. What you'd likely want to look for there
are indexes that have the last_idx_scan set to something far in the
past or set to NULL.

I guess you have never heard of the TREAT method of index management? :-D
- Test for duplicate indexes
- Reindex bloated indexes
- Eliminate unused indexes
- Add missing indexes
- Tune indexes for generic queries

The easy part of figuring out what to change, the hard part
(sometimes) is getting those changes into production safely; that's
the part I am focused on.

I'm curious to know if you've ever had to drop an index out of
production before? What did you think about when you'd just typed the
DROP INDEX command and were contemplating your future? How long did
you pause before pressing [Enter]?

ROFL... Uh... yes, I have had to do it at least a few times.

So, years ago I used to say things like "I wish we had a way to make
indexes invisible like they do in Oracle" on the regular; but as I
worked through several different implementations and their potential
effects, and had more and more exposure to more demanding Postgres
installations, my thinking evolved. I spoke with Sami a bit about this
off-list and he walked me through some of the Oracle documentation on
this (I had, at best, forgot the specifics), which I think was helpful
to better understand some of the allure of the alter index/guc method
for many people who are used to it (and this current version of the
implementation is very Oracle like), but it also crystalized my
feeling that an Oracle-style implementation would be a red herring
that can keep us from a better solution.

Can you list your proposed series of steps you'd recommend to a DBA
wishing to remove an index, assuming this feature exists in core as
you'd like it to?

Well, the series of steps differs depending on the nature of the
system being managed. If you are running on a single node with normal
traffic and resources, you just set the GUC to include the index you
want to be invisible, wait for a few days (maybe no one runs monthly
reports on this system?), take a quick look at your monitoring/stats
to make sure things seem copacetic, and then you drop the index and
reset the GUC.

But of course the people who I am most worried about are the ones who
are operating on high scale, high transaction, high connection,
"mission critical" systems... ie. people operating in high risk
environments, where things can go very bad very fast. Where safety
considerations are a critical part of every deployment.

In that type of environment, the GUC-only method enables you to
control changes at very precise levels, so you can do things like:
- run it ad-hoc at the session level to confirm that the explain plans
you get in production match your expectations.
- you can stay ad-hoc at the session level and run explain analyze and
confirm acceptable performance within your workload, and see what kind
of buffer impact you are going to have (typically overlooked, but a
potential landmine for outages, but I'll come back to this)
- because we are operating at the session level, we can then add this
on a per query basis at the application level, and in really high
traffic scenarios, you can use canary releases and/or feature flags to
ramp up those new queries into the live system.
- depending on how much risk you are concerned about, you can use this
session level method across queries individually, or at some point
roll it up to a user/application level. And again, we can roll it out
to different users at different times if you want.
- at some point when you feel confident that you have covered enough
angles, you set the GUC globally and let that marinate for a few more
weeks as needed.

And the funny thing is, at this point, once you have the guc put in
globally, and it's run for some number of weeks or months and everyone
is confident, you don't actually need the ALTER INDEX part any more;
you can just drop the index and be done with it. Now of course if you
aren't running at this kind of scale or don't have this level of risk,
you can speed run this a bit and go directly to the user level or skip
right to adding it globally, so the ease of use is on par with using
ALTER. But in any case where you do have elevated levels of risk, this
is actually less steps (and less risk) that having to use the
ALTER/guc method.

Earlier I mentioned the idea of monitoring buffer impact; let's talk
about that. I often hear people say that you should be doing things
like confirming your explain plans in development or have some type of
staging system where you do these kind of "experiments", as if a test
on a secondary system could really give you absolute confidence when
deploying to a system that automatically updates its settings (ie
pg_stats) at semi-random times with randomly sampled values; but in
any case, most people will at least agree that there is no way to
match up buffer usage across machines. That means if we are making
production changes that might have a significant impact on buffers, we
are doing something inherently dangerous. Well, dropping an index is
one of those things.

Imagine a scenario where you have a large index on a column and a
similar partial index on the same column, which are both used in
production for different queries, and therefore taking up some amount
of space within the buffer pool. When you make the partial index
invisible, the index is still maintained, and therefore it likely
still needs to maintain pages within the buffer pool to stay updated.
However, with queries now shifting to the full index, the full index
may very well need to pull in additional pages into the buffer pool
that it didn't need before, and this action can cause other pages from
some unknown object to get evicted. If you are lucky, this all works
itself and nothing bad happens, if you aren't, you may end up with a
server overloaded by latency in queries that aren't even related to
the indexes you're working on. (If you have a hard time seeing it with
partial indexes, the same can happen with consolidating indexes with
different INCLUDE statements, and certainly will be a scenario when
people look to drop indexes by way of skip-scan based plans). Now, is
it possible to handle this with the ALTER/guc method? Well, you can
mitigate it somewhat, but ironically to do so requires pushing out the
guc part of the ALTER/guc to all the places you would have pushed out
the GUC-only method, and that has to have been done BEFORE running
ALTER INDEX, so what does it really buy you?

I suppose while we're here, let me also make some observations about
how these methods differ when dealing with replica clusters. You
mentioned that one of the things you liked about the ALTER/guc method
is that it replicates the changes across all systems which makes it
easy to revert, however I believe that thinking is flawed. For
starters, any change that has to occur across the WAL stream is not
something that can be relied on to happen quickly; there are too many
other items that traverse that space that could end up blocking a
rollback from being applied in a timely fashion. The more complex the
replica cluster, the worse this is. One very common use case is to run
different workloads on different nodes, with the ALTER/guc method, you
are forcing users to make changes on a primary when they want to
target a workload that only runs on a replica. This means I have to
account for all potential workloads on all clusters before I can
safely start making changes, and to the degree that the ALTER/guc
gives me a safety net, that safety net is... to deploy a guc globally,
one at a time, on each individual server.

I feel like this email is already long, and tbh I could go on even
more, but hopefully I've covered enough to help explain some of the
issues that are involved here. I'm not trying to say that GUC-only is
a perfect solution, but I do think it handles every use case on par
with ALTER/guc, and enables some use cases ALTER/guc can't, especially
for people who have to operate in risk-first environments. And I get
it that some people are going to want a thing that looks very simple
or is familiar to how Oracle did it, but I can't help but think this
is one of those cases like how people used to always ask us to
implement UPSERT because that's what MySQL had, but instead we gave
them INSERT ON CONFLICT because it was the better solution to the
problem they (actually) had.

Robert Treat
https://xzilla.net

#98Sami Imseih
samimseih@gmail.com
In reply to: Robert Treat (#97)
Re: [PATCH] Re: Proposal to Enable/Disable Index using ALTER INDEX

In that type of environment, the GUC-only method enables you to
control changes at very precise levels, so you can do things like:
- run it ad-hoc at the session level to confirm that the explain plans
you get in production match your expectations.
- you can stay ad-hoc at the session level and run explain analyze and
confirm acceptable performance within your workload, and see what kind
of buffer impact you are going to have (typically overlooked, but a
potential landmine for outages, but I'll come back to this)
- because we are operating at the session level, we can then add this
on a per query basis at the application level, and in really high
traffic scenarios, you can use canary releases and/or feature flags to
ramp up those new queries into the live system.
- depending on how much risk you are concerned about, you can use this
session level method across queries individually, or at some point
roll it up to a user/application level. And again, we can roll it out
to different users at different times if you want.
- at some point when you feel confident that you have covered enough
angles, you set the GUC globally and let that marinate for a few more
weeks as needed.

Do we need this level of granular control in core, or should this be
delegated to other tools in the ecosystem, like pg_hint_plan? The de
facto tool for influencing planning.
There is probably some work that must happen in that extension to make
the use-cases above work, but it is something to consider.

With that said, I am not really opposed to a multi-value GUC that takes
in a list of index names, but I do have several concerns with that
approach being available in core:

1. The list of indexes getting too long, and the potential performance
impact of having to translate the index name to a relid to find which
index to make "invisible". I don't think a list of index relids will
be good from a usability perspective either.

2. A foot-gun such as adding an index name to my list, dropping the
index, recreating it with the same name, and now my new index is not
being used.

3. not sync'd up with the replica, so manual work is required there. That
could be seen as a positive aspect of this approach as well.

4. The above points speak on the level of maintenance required for this.

You mentioned that one of the things you liked about the ALTER/guc method
is that it replicates the changes across all systems which makes it
easy to revert, however I believe that thinking is flawed. For
starters, any change that has to occur across the WAL stream is not
something that can be relied on to happen quickly; there are too many
other items that traverse that space that could end up blocking a
rollback from being applied in a timely fashion.

This is not going to be unique to this feature though. Other critical
DDLs will be blocked, so this is a different problem, IMO.

but it also crystalized my
feeling that an Oracle-style implementation would be a red herring
that can keep us from a better solution.

Going back to this point, I still think that the ALTER option is useful
after the user's confidence is near 100% and they are ready to drop
the index for good, and which also gets replicated.

The GUC is useful for experimentation or for users that want to do a
slow rollout of dropping an index. We can discuss whether this should
be a multi-value setting or a boolean in core, or if it should be
delegated to an extension.

Essentially, I don't think we need to choose one or the other, but
perhaps we can improve upon the GUC.

--
Sami

#99David Rowley
dgrowleyml@gmail.com
In reply to: Robert Treat (#97)
Re: [PATCH] Re: Proposal to Enable/Disable Index using ALTER INDEX

On Sun, 8 Jun 2025 at 01:35, Robert Treat <rob@xzilla.net> wrote:

On Fri, Jun 6, 2025 at 8:04 PM David Rowley <dgrowleyml@gmail.com> wrote:

Can you list your proposed series of steps you'd recommend to a DBA
wishing to remove an index, assuming this feature exists in core as
you'd like it to?

Well, the series of steps differs depending on the nature of the
system being managed. If you are running on a single node with normal
traffic and resources, you just set the GUC to include the index you
want to be invisible, wait for a few days (maybe no one runs monthly
reports on this system?), take a quick look at your monitoring/stats
to make sure things seem copacetic, and then you drop the index and
reset the GUC.

Thanks for explaining.

What are your thoughts on cached plans? In this scenario, do you
assume that waiting a few days means that connections get reset and
prepared statements will have been replanned? Or do you think cached
plans don't matter in this scenario?

David

#100Robert Treat
rob@xzilla.net
In reply to: David Rowley (#99)
Re: [PATCH] Re: Proposal to Enable/Disable Index using ALTER INDEX

On Sat, Jun 7, 2025 at 9:17 PM David Rowley <dgrowleyml@gmail.com> wrote:

On Sun, 8 Jun 2025 at 01:35, Robert Treat <rob@xzilla.net> wrote:

On Fri, Jun 6, 2025 at 8:04 PM David Rowley <dgrowleyml@gmail.com> wrote:

Can you list your proposed series of steps you'd recommend to a DBA
wishing to remove an index, assuming this feature exists in core as
you'd like it to?

Well, the series of steps differs depending on the nature of the
system being managed. If you are running on a single node with normal
traffic and resources, you just set the GUC to include the index you
want to be invisible, wait for a few days (maybe no one runs monthly
reports on this system?), take a quick look at your monitoring/stats
to make sure things seem copacetic, and then you drop the index and
reset the GUC.

Thanks for explaining.

What are your thoughts on cached plans? In this scenario, do you
assume that waiting a few days means that connections get reset and
prepared statements will have been replanned? Or do you think cached
plans don't matter in this scenario?

Heh; I did say that the GUC model wasn't perfect, so good on you for
getting right to one of the more wonky parts. In practice, I actually
don't think it matters as much as one might think; IME there is a sort
of inverse relationship were the more sensitive you are to production
changes and/or running at high scale, the more likely you are going to
want to slow deploy / ramp up these changes, and doing things like
adding the GUC at the session level will likely require a connection
recycle anyway. Also keeping invisible indexes in place for days or
weeks is likely to be a common scenario, and again we don't normally
expect connections, or cached plans, to stay alive for weeks at a
time. Of course you can't dismiss this; you'd definitely have to
document that if they are worried about queries with cached plans the
best solution would be to recycle any connections that might have
existed before setting the guc in place. That may not sound ideal, but
I think in practice it is no worse than the practical effects of
thinking that ANALYZE will help keep your queries fast; sure it keeps
your statistics up to date, but if you are running cached plans for
indefinite periods of time, you wouldn't actually pick those up those
statistics changes*, which means cached plans are already susceptible
to degrading over time, and we are expecting people to recycle
connections regularly even if we don't say it very loud.

* As an aside, I once looked into implementing some kind of
pg_invalidate_cached_plans() function that would send a signal to all
backend to dump their plans; kind of like a global DISCARD ALL, but it
always seemed scarier than just recycling connections, so I gave up on
it pretty quick; maybe some would find that useful though?

Robert Treat
https://xzilla.net

#101David Rowley
dgrowleyml@gmail.com
In reply to: Robert Treat (#100)
Re: [PATCH] Re: Proposal to Enable/Disable Index using ALTER INDEX

On Mon, 9 Jun 2025 at 06:53, Robert Treat <rob@xzilla.net> wrote:

On Sat, Jun 7, 2025 at 9:17 PM David Rowley <dgrowleyml@gmail.com> wrote:

What are your thoughts on cached plans? In this scenario, do you
assume that waiting a few days means that connections get reset and
prepared statements will have been replanned? Or do you think cached
plans don't matter in this scenario?

Heh; I did say that the GUC model wasn't perfect, so good on you for
getting right to one of the more wonky parts. In practice, I actually
don't think it matters as much as one might think; IME there is a sort
of inverse relationship were the more sensitive you are to production
changes and/or running at high scale, the more likely you are going to
want to slow deploy / ramp up these changes, and doing things like
adding the GUC at the session level will likely require a connection
recycle anyway. Also keeping invisible indexes in place for days or
weeks is likely to be a common scenario, and again we don't normally
expect connections, or cached plans, to stay alive for weeks at a
time. Of course you can't dismiss this; you'd definitely have to
document that if they are worried about queries with cached plans the
best solution would be to recycle any connections that might have
existed before setting the guc in place. That may not sound ideal, but
I think in practice it is no worse than the practical effects of
thinking that ANALYZE will help keep your queries fast; sure it keeps
your statistics up to date, but if you are running cached plans for
indefinite periods of time, you wouldn't actually pick those up those
statistics changes*, which means cached plans are already susceptible
to degrading over time, and we are expecting people to recycle
connections regularly even if we don't say it very loud.

I agree that it doesn't seem ideal. I feel like if we're adding a
feature that we have to list a bunch of caveats in the documentation,
then we're doing something wrong. BTW, the ALTER INDEX will correctly
invalidate cached plans and does not suffer from the same issue.

My thoughts on this are that extensions are a better place to keep
solutions that work most of the time. Once you start committing quirky
things to Postgres, you sentence yourself to answering the same
question for possibly a few decades in the -bugs or -general mailing
list. I do my best to avoid that and feel we have enough of that
already, so I'm -1 on the GUC solution for this. I know there are a
few other people that are for it, so feel free to listen to them
instead.

Personally, I'd rather see us getting query hints in core and having
some method to specify a global hint to hint "not using index X". I'm
not holding my breath for that one.

David

#102Robert Treat
rob@xzilla.net
In reply to: David Rowley (#101)
Re: [PATCH] Re: Proposal to Enable/Disable Index using ALTER INDEX

On Sun, Jun 8, 2025 at 9:37 PM David Rowley <dgrowleyml@gmail.com> wrote:

On Mon, 9 Jun 2025 at 06:53, Robert Treat <rob@xzilla.net> wrote:

On Sat, Jun 7, 2025 at 9:17 PM David Rowley <dgrowleyml@gmail.com> wrote:

What are your thoughts on cached plans? In this scenario, do you
assume that waiting a few days means that connections get reset and
prepared statements will have been replanned? Or do you think cached
plans don't matter in this scenario?

Heh; I did say that the GUC model wasn't perfect, so good on you for
getting right to one of the more wonky parts. In practice, I actually
don't think it matters as much as one might think; IME there is a sort
of inverse relationship were the more sensitive you are to production
changes and/or running at high scale, the more likely you are going to
want to slow deploy / ramp up these changes, and doing things like
adding the GUC at the session level will likely require a connection
recycle anyway. Also keeping invisible indexes in place for days or
weeks is likely to be a common scenario, and again we don't normally
expect connections, or cached plans, to stay alive for weeks at a
time. Of course you can't dismiss this; you'd definitely have to
document that if they are worried about queries with cached plans the
best solution would be to recycle any connections that might have
existed before setting the guc in place. That may not sound ideal, but
I think in practice it is no worse than the practical effects of
thinking that ANALYZE will help keep your queries fast; sure it keeps
your statistics up to date, but if you are running cached plans for
indefinite periods of time, you wouldn't actually pick those up those
statistics changes*, which means cached plans are already susceptible
to degrading over time, and we are expecting people to recycle
connections regularly even if we don't say it very loud.

I agree that it doesn't seem ideal. I feel like if we're adding a
feature that we have to list a bunch of caveats in the documentation,
then we're doing something wrong. BTW, the ALTER INDEX will correctly
invalidate cached plans and does not suffer from the same issue.

While the ALTER INDEX provides a simple way to do cache invalidation,
for practical application you still have most of the same issues and
need to jump through many of the same guc hoops with
force_invisible_index, which is a large part of why this is such a red
herring.

My thoughts on this are that extensions are a better place to keep
solutions that work most of the time. Once you start committing quirky
things to Postgres, you sentence yourself to answering the same
question for possibly a few decades in the -bugs or -general mailing
list. I do my best to avoid that and feel we have enough of that
already, so I'm -1 on the GUC solution for this. I know there are a
few other people that are for it, so feel free to listen to them
instead.

I hear you wrt explaining quirky things to users; you wouldn't believe
the level of confusion I got when I started explaining
"plan_cache_mode" to users when v12 rolled out. I'd guess the vast
majority of users have still never heard of this guc and have no idea
that Postgres behaves like this, which is another reason why I'd
rather not optimize for a very small segment of the user base at the
expense of a much larger set of users.

And to be clear, this isn't a case of a GUC solution vs an ALTER
solution. There is a reason that the proposed ALTER solution contains
a GUC as well, and why Oracle had to make use of a session flag in
their implementation. You are going to have a guc either way, which
means you are going to have to explain a bunch of these different
caveats in BOTH solutions. It's just that in one of the solutions, you
are further entangling the usage with DDL changes (and the additional
caveats that come with that).

Robert Treat
https://xzilla.net

#103David Rowley
dgrowleyml@gmail.com
In reply to: Robert Treat (#102)
Re: [PATCH] Re: Proposal to Enable/Disable Index using ALTER INDEX

On Tue, 10 Jun 2025 at 04:40, Robert Treat <rob@xzilla.net> wrote:

You are going to have a guc either way, which
means you are going to have to explain a bunch of these different
caveats in BOTH solutions. It's just that in one of the solutions, you
are further entangling the usage with DDL changes (and the additional
caveats that come with that).

IMO, having this GUC to force the use of invisible indexes is quite
strange. In my view, it detracts from the guarantees that you're meant
to get from disabling indexes. What if some connection has
use_invisible_index set to true? The DBA might assume all is well
after having seen nobody complain and then drop the index. The user
might then complain.

David

#104Sami Imseih
samimseih@gmail.com
In reply to: David Rowley (#103)
Re: [PATCH] Re: Proposal to Enable/Disable Index using ALTER INDEX

IMO, having this GUC to force the use of invisible indexes is quite
strange. In my view, it detracts from the guarantees that you're meant
to get from disabling indexes. What if some connection has
use_invisible_index set to true? The DBA might assume all is well
after having seen nobody complain and then drop the index. The user
might then complain.

Sure, this may occur. I can also imagine cases where an index is made
visible only for certain workloads, intentionally. But such efforts should
be coordinated by application teams and DBAs. Someone would need to modify
this GUC at the connection level, alter the database, or change the session
via application code. An ad-hoc connection enabling this GUC is unlikely to
be an issue.

I don't see how we could provide the INVISIBLE index DDL without also
providing this boolean GUC. If a user creates an index that is initially
INVISIBLE, they need a GUC to try it out before deciding to make it
visible.

It was also pointed out in the thread above that this GUC can serve as a
backstop for replicas if the DDL to make an index visible is delayed.

--

Sami

#105Shayon Mukherjee
shayonj@gmail.com
In reply to: Sami Imseih (#104)
Re: [PATCH] Proposal to Enable/Disable Index using ALTER INDEX

On Jun 11, 2025, at 9:00 AM, Sami Imseih <samimseih@gmail.com> wrote:

IMO, having this GUC to force the use of invisible indexes is quite
strange. In my view, it detracts from the guarantees that you're meant
to get from disabling indexes. What if some connection has
use_invisible_index set to true? The DBA might assume all is well
after having seen nobody complain and then drop the index. The user
might then complain.

Sure, this may occur. I can also imagine cases where an index is made
visible only for certain workloads, intentionally. But such efforts should
be coordinated by application teams and DBAs. Someone would need to modify
this GUC at the connection level, alter the database, or change the session
via application code. An ad-hoc connection enabling this GUC is unlikely to
be an issue.

I don't see how we could provide the INVISIBLE index DDL without also
providing this boolean GUC. If a user creates an index that is initially
INVISIBLE, they need a GUC to try it out before deciding to make it
visible.

It was also pointed out in the thread above that this GUC can serve as a
backstop for replicas if the DDL to make an index visible is delayed.

Hello,

Thank you everyone for all the discussions and also to Robert Treat for feedback and the operational considerations.

It seems like there are multiple ways to solve this problem, which is encouraging. From the discussion, there appears to be consensus on few things as well, including the DDL approach, which I personally am a proponent for as well.

I believe this is a valuable feature for DBAs and engineers working with large databases. Esp since it provides the confidence to "turn off" an index to observe the impact through their observability tools and make an informed decision about whether to drop it. If they're wrong, they can quickly rollback by making the index visible again, rather than waiting for a full index rebuild that can take 30 minutes to hours.

The primary use case I have in mind is for helping engineers (ones not so seasoned like DBAs) decide whether to drop *existing* indexes. For new indexes, I expect most users would create them in visible mode (the default). Or so has been my experience so far.

The GUC component opens the door for additional workflows, such as creating an index as initially invisible (like Sami points out) and testing its performance before making it visible. I originally wasn't thinking it this way, but this demonstrates the flexibility of the feature and accommodates different development approaches.

As Robert noted, both approaches have trade-offs around operational safety and granular control. However, I think the DDL approach provides the right balance of simplicity and system-wide consistency that most users need, while the GUC still enables experimentation for those who want it.

I'm very much committed to iterating on this patch to address any remaining feedback and help make progress on this. Is there something we can do here in the essence of "start small, think big", perhaps?

Thanks
Shayon

#106Merlin Moncure
mmoncure@gmail.com
In reply to: Shayon Mukherjee (#105)
Re: [PATCH] Proposal to Enable/Disable Index using ALTER INDEX

On Sat, Jun 21, 2025 at 8:38 AM Shayon Mukherjee <shayonj@gmail.com> wrote:

On Jun 11, 2025, at 9:00 AM, Sami Imseih <samimseih@gmail.com> wrote:

IMO, having this GUC to force the use of invisible indexes is quite

strange. In my view, it detracts from the guarantees that you're meant
to get from disabling indexes. What if some connection has
use_invisible_index set to true? The DBA might assume all is well
after having seen nobody complain and then drop the index. The user
might then complain.

Sure, this may occur. I can also imagine cases where an index is made
visible only for certain workloads, intentionally. But such efforts should
be coordinated by application teams and DBAs. Someone would need to modify
this GUC at the connection level, alter the database, or change the session
via application code. An ad-hoc connection enabling this GUC is unlikely to
be an issue.

I don't see how we could provide the INVISIBLE index DDL without also
providing this boolean GUC. If a user creates an index that is initially
INVISIBLE, they need a GUC to try it out before deciding to make it
visible.

It was also pointed out in the thread above that this GUC can serve as a
backstop for replicas if the DDL to make an index visible is delayed.

Hello,

Thank you everyone for all the discussions and also to Robert Treat for
feedback and the operational considerations.

It seems like there are multiple ways to solve this problem, which is
encouraging. From the discussion, there appears to be consensus on few
things as well, including the DDL approach, which I personally am a
proponent for as well.

I believe this is a valuable feature for DBAs and engineers working with
large databases. Esp since it provides the confidence to "turn off" an
index to observe the impact through their observability tools and make an
informed decision about whether to drop it. If they're wrong, they can
quickly rollback by making the index visible again, rather than waiting for
a full index rebuild that can take 30 minutes to hours.

The primary use case I have in mind is for helping engineers (ones not so
seasoned like DBAs) decide whether to drop *existing* indexes. For new
indexes, I expect most users would create them in visible mode (the
default). Or so has been my experience so far.

What I would be using this for is when the server is choosing the wrong
index, often in multi column index scenarios. The server can be obtuse in
those situations. So I see this as a query optimization aid rather than a
'should I drop this?' Given that there are several ways to do that
already. I can see scenarios where I'd want the index backed constraint
to never be used for some/all queries.

ALTER driving this seems ok. It seems more of a planner directive to me
but having potential permanent configuration (vs mostly temporary needs)
tips the scale IMO.

ENABLE | DISABLE seems off. I would take it further to, ENABLE | DISABLE
OPTIMIZATION for clarify and to leave room for syntax expansion.

Nice stuff. Did not review patch

merlin

#107Junwang Zhao
zhjwpku@gmail.com
In reply to: Shayon Mukherjee (#105)
Re: [PATCH] Proposal to Enable/Disable Index using ALTER INDEX

Hi Shayon,

On Sat, Jun 21, 2025 at 9:38 PM Shayon Mukherjee <shayonj@gmail.com> wrote:

On Jun 11, 2025, at 9:00 AM, Sami Imseih <samimseih@gmail.com> wrote:

IMO, having this GUC to force the use of invisible indexes is quite
strange. In my view, it detracts from the guarantees that you're meant
to get from disabling indexes. What if some connection has
use_invisible_index set to true? The DBA might assume all is well
after having seen nobody complain and then drop the index. The user
might then complain.

Sure, this may occur. I can also imagine cases where an index is made
visible only for certain workloads, intentionally. But such efforts should
be coordinated by application teams and DBAs. Someone would need to modify
this GUC at the connection level, alter the database, or change the session
via application code. An ad-hoc connection enabling this GUC is unlikely to
be an issue.

I don't see how we could provide the INVISIBLE index DDL without also
providing this boolean GUC. If a user creates an index that is initially
INVISIBLE, they need a GUC to try it out before deciding to make it
visible.

It was also pointed out in the thread above that this GUC can serve as a
backstop for replicas if the DDL to make an index visible is delayed.

Hello,

Thank you everyone for all the discussions and also to Robert Treat for feedback and the operational considerations.

It seems like there are multiple ways to solve this problem, which is encouraging. From the discussion, there appears to be consensus on few things as well, including the DDL approach, which I personally am a proponent for as well.

I believe this is a valuable feature for DBAs and engineers working with large databases. Esp since it provides the confidence to "turn off" an index to observe the impact through their observability tools and make an informed decision about whether to drop it. If they're wrong, they can quickly rollback by making the index visible again, rather than waiting for a full index rebuild that can take 30 minutes to hours.

The primary use case I have in mind is for helping engineers (ones not so seasoned like DBAs) decide whether to drop *existing* indexes. For new indexes, I expect most users would create them in visible mode (the default). Or so has been my experience so far.

The GUC component opens the door for additional workflows, such as creating an index as initially invisible (like Sami points out) and testing its performance before making it visible. I originally wasn't thinking it this way, but this demonstrates the flexibility of the feature and accommodates different development approaches.

As Robert noted, both approaches have trade-offs around operational safety and granular control. However, I think the DDL approach provides the right balance of simplicity and system-wide consistency that most users need, while the GUC still enables experimentation for those who want it.

I'm very much committed to iterating on this patch to address any remaining feedback and help make progress on this. Is there something we can do here in the essence of "start small, think big", perhaps?

Thanks
Shayon

Based on your analysis, I think the patch could be split into two
parts: one focusing on the DDL approach and the other on the
additional GUC control.

From reading the discussions, it seems that the GUC control
depends on the DDL approach (eg. creating an index as initially
invisible and making it visible later).

Therefore, maybe the DDL approach can be committed first
and extend the GUC control later as needed?

I read the v18 patch, I think the following changes should not
be included:

diff --git a/src/interfaces/ecpg/test/regression.diffs
b/src/interfaces/ecpg/test/regression.diffs
new file mode 100644
index 0000000000..e69de29bb2
diff --git a/src/interfaces/ecpg/test/regression.out
b/src/interfaces/ecpg/test/regression.out
new file mode 100644
index 0000000000..cb633f4d71
--- /dev/null
+++ b/src/interfaces/ecpg/test/regression.out
@@ -0,0 +1,55 @@
+# initializing database system by copying initdb template
+# using temp instance on port 65312 with PID 30031
+ok 1         - compat_informix/dec_test                  563 ms
+ok 2         - compat_informix/charfuncs                 255 ms
+ok 3         - compat_informix/rfmtdate                  355 ms

--
Regards
Junwang Zhao

#108Robert Treat
rob@xzilla.net
In reply to: Merlin Moncure (#106)
Re: [PATCH] Proposal to Enable/Disable Index using ALTER INDEX

On Sat, Jun 21, 2025 at 10:59 AM Merlin Moncure <mmoncure@gmail.com> wrote:

On Sat, Jun 21, 2025 at 8:38 AM Shayon Mukherjee <shayonj@gmail.com> wrote:

The primary use case I have in mind is for helping engineers (ones not so seasoned like DBAs) decide whether to drop *existing* indexes. For new indexes, I expect most users would create them in visible mode (the default). Or so has been my experience so far.

+1

What I would be using this for is when the server is choosing the wrong index, often in multi column index scenarios. The server can be obtuse in those situations. So I see this as a query optimization aid rather than a 'should I drop this?' Given that there are several ways to do that already. I can see scenarios where I'd want the index backed constraint to never be used for some/all queries.

ALTER driving this seems ok. It seems more of a planner directive to me but having potential permanent configuration (vs mostly temporary needs) tips the scale IMO.

If your use case falls along the lines of modifying planner decisions,
a DDL based interface is really the wrong interface for that; it
forces system wide impact and provides no ability to work in a per
query/connection/role/etc type manner, and is the most susceptible to
having rollback issues. These types of issues have always been
resolved through GUCs, which again, fits the use case here as well. I
guess I'll caveat that with the note that your use case is already
addressable using pg_hint_plan, which operates using sql comments, but
I think we're trying to not mention query hints in this thread :-)

Robert Treat
https://xzilla.net

#109Robert Treat
rob@xzilla.net
In reply to: Shayon Mukherjee (#105)
Re: [PATCH] Proposal to Enable/Disable Index using ALTER INDEX

On Sat, Jun 21, 2025 at 7:37 AM Shayon Mukherjee <shayonj@gmail.com> wrote:

On Jun 11, 2025, at 9:00 AM, Sami Imseih <samimseih@gmail.com> wrote:

IMO, having this GUC to force the use of invisible indexes is quite
strange. In my view, it detracts from the guarantees that you're meant
to get from disabling indexes. What if some connection has
use_invisible_index set to true? The DBA might assume all is well
after having seen nobody complain and then drop the index. The user
might then complain.

Sure, this may occur. I can also imagine cases where an index is made
visible only for certain workloads, intentionally. But such efforts should
be coordinated by application teams and DBAs. Someone would need to modify
this GUC at the connection level, alter the database, or change the session
via application code. An ad-hoc connection enabling this GUC is unlikely to
be an issue.

I don't see how we could provide the INVISIBLE index DDL without also
providing this boolean GUC. If a user creates an index that is initially
INVISIBLE, they need a GUC to try it out before deciding to make it
visible.

It was also pointed out in the thread above that this GUC can serve as a
backstop for replicas if the DDL to make an index visible is delayed.

Hello,

Thank you everyone for all the discussions and also to Robert Treat for feedback and the operational considerations.

It seems like there are multiple ways to solve this problem, which is encouraging. From the discussion, there appears to be consensus on few things as well, including the DDL approach, which I personally am a proponent for as well.

I believe this is a valuable feature for DBAs and engineers working with large databases. Esp since it provides the confidence to "turn off" an index to observe the impact through their observability tools and make an informed decision about whether to drop it. If they're wrong, they can quickly rollback by making the index visible again, rather than waiting for a full index rebuild that can take 30 minutes to hours.

The primary use case I have in mind is for helping engineers (ones not so seasoned like DBAs) decide whether to drop *existing* indexes. For new indexes, I expect most users would create them in visible mode (the default). Or so has been my experience so far.

The GUC component opens the door for additional workflows, such as creating an index as initially invisible (like Sami points out) and testing its performance before making it visible. I originally wasn't thinking it this way, but this demonstrates the flexibility of the feature and accommodates different development approaches.

As Robert noted, both approaches have trade-offs around operational safety and granular control. However, I think the DDL approach provides the right balance of simplicity and system-wide consistency that most users need, while the GUC still enables experimentation for those who want it.

I'm very much committed to iterating on this patch to address any remaining feedback and help make progress on this. Is there something we can do here in the essence of "start small, think big", perhaps?

Glad to hear you are still interested, slightly disheartened by the
general lack of concern around operational safety in this thread. I
actually think what you have done covers a lot of the ground for
multiple implementations, so I'm optimistic we can get something for
19.

I was thinking about this some more over the weekend and it does seem
like you can't get away from doing something with DDL; even though it
is the wrong mental model... like when your AC is running but you
don't think it is cool enough, so you turn it down farther, as if it
would blow colder air... but that isn't how AC actually work... it
seems you can't eliminate the desire for this mental model entirely.
Which to be clear, I am not against, it's just a bad tool for the hard
cases, but not in every case. Anyway, if I were picking this up, I
would separate out the two ideas; as I laid out in my email to David,
the GUC solution can stand on it's own without the DDL implementation,
and I would do that first, and then add a simplified DDL
implementation after the fact. Of course it could be done the other
way around, but I think you're more likely to land on the correct GUC
implementation if it isn't mixed up with DDL, and the best way to
assure that is by not having the DDL for the initial patch. Just my
.02, but happy to help spec it out further.

Robert Treat
https://xzilla.net

#110Shayon Mukherjee
shayonj@gmail.com
In reply to: Robert Treat (#109)
Re: [PATCH] Proposal to Enable/Disable Index using ALTER INDEX

On Jun 23, 2025, at 10:14 AM, Robert Treat <rob@xzilla.net> wrote:

Sorry for the late response, been busy at work :D.

Glad to hear you are still interested, slightly disheartened by the
general lack of concern around operational safety in this thread. I
actually think what you have done covers a lot of the ground for
multiple implementations, so I'm optimistic we can get something for
19.

Just for my own learning and mental model - what would be a good way to understand the change that wasn’t operationally safe?

I was thinking about this some more over the weekend and it does seem
like you can't get away from doing something with DDL; even though it
is the wrong mental model... like when your AC is running but you
don't think it is cool enough, so you turn it down farther, as if it
would blow colder air... but that isn't how AC actually work... it
seems you can't eliminate the desire for this mental model entirely.
Which to be clear, I am not against, it's just a bad tool for the hard
cases, but not in every case. Anyway, if I were picking this up, I
would separate out the two ideas; as I laid out in my email to David,
the GUC solution can stand on it's own without the DDL implementation,
and I would do that first, and then add a simplified DDL
implementation after the fact. Of course it could be done the other
way around, but I think you're more likely to land on the correct GUC
implementation if it isn't mixed up with DDL, and the best way to
assure that is by not having the DDL for the initial patch. Just my
.02, but happy to help spec it out further.

I am happy to split this into two, however I think starting with GUC first may not achieve a lot of cases that David and I were talking about earlier in the thread, perhaps? Where, if you want quick feedback without needing to make application / session / connection level changes (i.e GUC) then you can quickly do it via the ALTER statement. Happy to redo the patch and just keep ALTER for v1 accordingly, if it still makes sense.

Would folks have any preference between the two approaches?

Thank you
Shayon

#111Robert Treat
rob@xzilla.net
In reply to: Shayon Mukherjee (#110)
Re: [PATCH] Proposal to Enable/Disable Index using ALTER INDEX

On Tue, Jul 15, 2025 at 8:19 AM Shayon Mukherjee <shayonj@gmail.com> wrote:

On Jun 23, 2025, at 10:14 AM, Robert Treat <rob@xzilla.net> wrote:
Glad to hear you are still interested, slightly disheartened by the
general lack of concern around operational safety in this thread. I
actually think what you have done covers a lot of the ground for
multiple implementations, so I'm optimistic we can get something for
19.

Just for my own learning and mental model - what would be a good way to understand the change that wasn’t operationally safe?

Generally speaking, the two biggest factors for operational safety are
the ability to slowly ramp up changes in a controlled fashion, and
conversely the ability to quickly reverse them. On its surface, the
ALTER feature looks like it passes both of these tests because (in
simple cases) it appears better than drop/create index process alone;
indeed, the ability to "turn off" an index before dropping it feels
like a slower roll out than dropping it, and the ability to "turn it
back on" seems like a much quicker reversal than having to recreate
the index. Our problem is that this only gives the appearance of
safety without having provided any significant improvement in system
safety, especially in more complex and/or demanding setups. With
regards to roll out specifically, the ALTER method is no safer than
drop index because both use DDL which means they are both open to
blocking or being blocked by conflicting queries, which increase
operational risk within the system. Similarly, the nature of the DDL
change also requires that all sessions be impacted everywhere at once;
there is no way to slowly roll the change to some segment of the
database or some specific workload within the system. So it fails the
first test. With regards to the ability to quickly reverse the change,
it does beat the need to rebuild an index, but that only helps in a
very small subset of the typical use cases for this feature; ie where
you are concerned that your server might get "swamped" by poorly
performing queries while the index rebuilds. But that's a pretty low
level version of the problem; on very busy systems and/or system with
delicately balanced buffer caching, even a small pause measured in
seconds could be enough to bring a system down, and again our use of
DDL opens us up to delays from conflicting queries, untimely
wraparound vacuums, concurrent WAL traffic in the case of wanting to
do this across replica trees (which you can't not do). So we generally
fail the second test for a large portion of the use cases involved.
And maybe that would be ok if we didn't have a way to solve this
problem that doesn't fail these tests, but we do, which is through
using a GUC.

I was thinking about this some more over the weekend and it does seem
like you can't get away from doing something with DDL; even though it
is the wrong mental model... like when your AC is running but you
don't think it is cool enough, so you turn it down farther, as if it
would blow colder air... but that isn't how AC actually work... it
seems you can't eliminate the desire for this mental model entirely.
Which to be clear, I am not against, it's just a bad tool for the hard
cases, but not in every case. Anyway, if I were picking this up, I
would separate out the two ideas; as I laid out in my email to David,
the GUC solution can stand on it's own without the DDL implementation,
and I would do that first, and then add a simplified DDL
implementation after the fact. Of course it could be done the other
way around, but I think you're more likely to land on the correct GUC
implementation if it isn't mixed up with DDL, and the best way to
assure that is by not having the DDL for the initial patch. Just my
.02, but happy to help spec it out further.

I am happy to split this into two, however I think starting with GUC first may not achieve a lot of cases that David and I were talking about earlier in the thread, perhaps? Where, if you want quick feedback without needing to make application / session / connection level changes (i.e GUC) then you can quickly do it via the ALTER statement. Happy to redo the patch and just keep ALTER for v1 accordingly, if it still makes sense.

I think it is much more the other way around; the GUC handles far more
of the potential use cases that you might want to use the ALTER for,
and the ALTER clearly falls short of what the GUC can do. (Side note,
remember you can modify the GUC at the database level. And if you
really want to get ambitious, GUCs can be extended to work through
ALTER TABLE).

Would folks have any preference between the two approaches?

Contrary to how it sounds, I'm not actually opposed to having both :-)
But I am very concerned that an implementation which does ALTER first
sets a sort of anchoring bias that would affect how the GUC feature
gets implemented, which is how I suspect Oracle ended up with their
crappy implementation. I don't think this happens in reverse; ie. the
GUC first implementation handles most of the heavy lifting so the
ALTER only needs to cover the suite spot of the use cases that it can
actually help with.

Robert Treat
https://xzilla.net

#112David Rowley
dgrowleyml@gmail.com
In reply to: Robert Treat (#111)
Re: [PATCH] Proposal to Enable/Disable Index using ALTER INDEX

On Wed, 16 Jul 2025 at 05:59, Robert Treat <rob@xzilla.net> wrote:

operational risk within the system. Similarly, the nature of the DDL
change also requires that all sessions be impacted everywhere at once;
there is no way to slowly roll the change to some segment of the
database or some specific workload within the system.

IMO, sounds like your method for safety here is to slowly walk your
bull into the china shop. Wouldn't it be much better to learn where or
confirm the index isn't being used before you go turning it off for
various queries? I'm stumped at why your method for removing the index
amounts to closing your eyes and doing your best to narrow the blast
radius of the trial and error method.

regards to roll out specifically, the ALTER method is no safer than
drop index because both use DDL which means they are both open to
blocking or being blocked by conflicting queries, which increase

Aside from not having to recreate the index, I agree with this part.
It's a genuine concern. If some query switches to a Seq Scan and the
queries to that table start taking a week to execute, then it'll be a
long wait before you can get an AccessExclusiveLock on the table
again. I think our mental models for this differ, however. In my
imagination, I've checked that the index is unused before I disable
it. It seems like in your model, you're going to disable it and
measure the yield of the resulting explosion.

The latest patch seems to be using a ShareUpdateExclusiveLock, so it
looks like those concurrent seq scans won't block making the index
visible again.

My concern with the GUC approach is that:

1. It'll be yet another crappy way to hint what you want the planner
to do. (The other way being enable_* GUCs)
2. There's no plan cache invalidation when changing the GUC.
3. Standby servers may get forgotten about
4. It encourages trial and error methodology for removing indexes
5. All the committers who showed any hints at liking this method have
disappeared from the thread.

My concern with #1 is that when we one day do get query hints, we'll
be left with a bunch of redundant ways to influence planner behaviour.

Maybe you could get the behaviour you want by some additions to
pg_hint_plan. Looking at [1]https://github.com/ossc-db/pg_hint_plan/blob/master/docs/hint_table.md, if query_id could be NULL to apply to
all queries and there was some way of doing "No IndexScan(*
index_name)", would that get you what you want?

David

[1]: https://github.com/ossc-db/pg_hint_plan/blob/master/docs/hint_table.md

#113Sami Imseih
samimseih@gmail.com
In reply to: David Rowley (#112)
Re: [PATCH] Proposal to Enable/Disable Index using ALTER INDEX

My concern with #1 is that when we one day do get query hints, we'll
be left with a bunch of redundant ways to influence planner behaviour.

The GUC is more than just a hint. It can serve as a hint, but it also offers
operational benefits. For example, if I mark an index as invisible and that
only affects a subset of my workload, I don’t need to make the index visible
again. Instead, I can tune that specific workload to operate without it.

Once I’m confident the workload performs well, I can safely drop the index.

I’d argue we should not provide the ALTER option without the GUC, for
more granular control.
Regards,

Sami

#114David G. Johnston
david.g.johnston@gmail.com
In reply to: Sami Imseih (#113)
Re: Proposal to Enable/Disable Index using ALTER INDEX

On Thursday, July 17, 2025, Sami Imseih <samimseih@gmail.com> wrote:

My concern with #1 is that when we one day do get query hints, we'll

be left with a bunch of redundant ways to influence planner behaviour.

I’d rather not stop accepting improvements of this sort until we get a
proper planner hint into core.

I’d argue we should not provide the ALTER option without the GUC, for

more granular control.

Agreed. DBAs should do research. Optimistic ones can then use alter index
to efficiently deploy their informed decisions throughout their systems.
They have GUC as a temporary fallback mechanism should they need it.
Pessimistic ones can just micro-manage using the GUC.

Unless someone is willing to try and get “The PostgreSQL team’s blessed
guide to index management” into the documentation as well we should
probably just accept this will be a bit tool belt approach and there will
be tools that for one person’s approach are not useful. That does not mean
they need to be removed (so long as they were added intentionally).

David J.

#115David Rowley
dgrowleyml@gmail.com
In reply to: Sami Imseih (#113)
Re: [PATCH] Proposal to Enable/Disable Index using ALTER INDEX

On Fri, 18 Jul 2025 at 14:25, Sami Imseih <samimseih@gmail.com> wrote:

I’d argue we should not provide the ALTER option without the GUC, for
more granular control.

If you mean the use_invisible_index GUC, then for transparency here,
I'm not in favour of that. I do understand that this might be useful
when trying to get a lagged hot-standby which is desperately
performing Seq Scans back up and running again while waiting on the
replay of the ALTER TABLE VISIBLE, but I just don't feel comfortable
being the committer/forever-owner of having a GUC that overwrites
something that's explicitly written in the system catalogue tables
that is disabled. It's just too magical for my liking. I don't think
we have anything like that today.

Other committers might feel differently, so if the general consensus
is ALTER TABLE+GUC, then I'll leave it to them. I'm by no means saying
this to try and influence the discussion here. If the ALTER TABLE
alone is not seen as useful and I'm the only one who thinks it would
be useful by itself, then I'll just back away from this and let
someone else pick it up.

David

#116Sami Imseih
samimseih@gmail.com
In reply to: David G. Johnston (#114)
Re: Proposal to Enable/Disable Index using ALTER INDEX

Unless someone is willing to try and get “The PostgreSQL team’s blessed guide to index management”
into the documentation

I really doubt we can agree on one set of index management guidelines.
If anything, this thread has proven there are many ways to bake this
cake :) and all approaches have merit.

we should probably just accept this will be a bit tool belt approach and
there will be tools that for one person’s approach are not useful.

+1

but I just don't feel comfortable
being the committer/forever-owner of having a GUC that overwrites
something that's explicitly written in the system catalogue tables
that is disabled.

That's fair

Other committers might feel differently, so if the general consensus
is ALTER TABLE+GUC, then I'll leave it to them. I'm by no means saying
this to try and influence the discussion here. If the ALTER TABLE
alone is not seen as useful

If we only go with the ALTER, my concern is there is really no way an extension
( i.e. pg_hint_plan ) can even provide the behavior of this GUC. If the value is
'invisible' in the catalog, the index is no longer available to extensions via
RelOptInfo->indexlist, and it cannot be forced to be considered for planning by
the extension. So, unless we provide the GUC in-core, it will not be
possible for it
to be achieved by extensions. Maybe someone can prove me wrong here.

--
Sami

#117Robert Treat
rob@xzilla.net
In reply to: David Rowley (#112)
Re: [PATCH] Proposal to Enable/Disable Index using ALTER INDEX

On Thu, Jul 17, 2025 at 9:49 PM David Rowley <dgrowleyml@gmail.com> wrote:

On Wed, 16 Jul 2025 at 05:59, Robert Treat <rob@xzilla.net> wrote:

operational risk within the system. Similarly, the nature of the DDL
change also requires that all sessions be impacted everywhere at once;
there is no way to slowly roll the change to some segment of the
database or some specific workload within the system.

IMO, sounds like your method for safety here is to slowly walk your
bull into the china shop. Wouldn't it be much better to learn where or
confirm the index isn't being used before you go turning it off for
various queries? I'm stumped at why your method for removing the index
amounts to closing your eyes and doing your best to narrow the blast
radius of the trial and error method.

regards to roll out specifically, the ALTER method is no safer than
drop index because both use DDL which means they are both open to
blocking or being blocked by conflicting queries, which increase

Aside from not having to recreate the index, I agree with this part.
It's a genuine concern. If some query switches to a Seq Scan and the
queries to that table start taking a week to execute, then it'll be a
long wait before you can get an AccessExclusiveLock on the table
again. I think our mental models for this differ, however. In my
imagination, I've checked that the index is unused before I disable
it. It seems like in your model, you're going to disable it and
measure the yield of the resulting explosion.

The whole premise of this feature is that there is no way to have
certainty that an index is truly unused. I can assure you that I've
done just as much due diligence as you have (perhaps more) to
determine that the index is unused, but if that were enough to ensure
safety, we wouldn't need invisible indexes in the first place; we
could just drop the index.

Once we admit that neither of us have operational safety, the question
becomes just how close can we get people to certainty, and how can we
most limit the fallout from being wrong. In my world, I'd never have
to worry about a plan flipping to sequential scan causing a query to
hold locks for a week because the server will have certainly crashed
within minutes from the overwhelming level of traffic said sequential
scan brings, so if the solution requires heavy locks and global
application (like alter would), it will still be extremely risky in
heavy production workloads. In short, we're both walking a bull
through the china shop, but it would seem mine is much more
temperamental than yours.

Robert Treat
https://xzilla.net

#118Sami Imseih
samimseih@gmail.com
In reply to: Robert Treat (#117)
Re: [PATCH] Proposal to Enable/Disable Index using ALTER INDEX

it will still be extremely risky in
heavy production workloads. In short, we're both walking a bull
through the china shop, but it would seem mine is much more
temperamental than yours.

Robert, Could you describe the GUC you would like to see?

Also, I'd like to ask. what would be the argument against offering both options,
ALTER and a GUC to override the catalog, as currently proposed in the patch?

This conversation has been mainly GUC is better than ALTER, or vice versa.

It is clear, at least to me, there are merits in both approaches, so
what would be
the argument against making both options available ( maybe with a GUC that
could be more useful than a simple boolean )?

--

Sami

#119Robert Treat
rob@xzilla.net
In reply to: Sami Imseih (#118)
Re: [PATCH] Proposal to Enable/Disable Index using ALTER INDEX

On Mon, Jul 21, 2025 at 1:17 PM Sami Imseih <samimseih@gmail.com> wrote:

it will still be extremely risky in
heavy production workloads. In short, we're both walking a bull
through the china shop, but it would seem mine is much more
temperamental than yours.

Robert, Could you describe the GUC you would like to see?

Also, I'd like to ask. what would be the argument against offering both options,
ALTER and a GUC to override the catalog, as currently proposed in the patch?

This conversation has been mainly GUC is better than ALTER, or vice versa.

It is clear, at least to me, there are merits in both approaches, so
what would be
the argument against making both options available ( maybe with a GUC that
could be more useful than a simple boolean )?

Just to reiterate, I am not against having both a GUC and ALTER
option, if implemented correctly. Like David, I don't have good
feelings about the ALTER / use_invisible_index GUC overwriting
behavior that is explicitly written in the catalog, and I see no
reason to settle for a technically awkward solution when I think it
also delivers a poor user interface that will be hard to reason about
and/or debug in production.

So I think the "right" interface looks something like a GUC that would
be something like "ignore_index_planning" which takes a csv list of
index names that the planner would ignore. On its own, this provides
as much flexibility as we can offer when attempting to change index
visibility, since it would be set global/local/etc, and could be set
on some, none, or some combo thereof within replica tree environments.
You can make that convoluted, but it is operating like other GUCs.

This also seems compatible with the implementation approach discussed
by PeterE, Tom, and Haas earlier upthread (1)(2) with regard to
providing a list of names and filtering them out. (There could be
other ways of implementing it, but this certainly seems to cover a lot
of the ground we'd want covered).

I know one concern of this method is that this could introduce some
parsing overhead if people choose to use large lists of indexes, but I
think that's generally ok as long as it is documented. Our typical use
case is expected to be one or maybe a few at most, indexes, but if
people feel strongly they need to run with dozens and dozens of
indexes listed, there will be a trade off, similar to other GUCs/tools
(think track_activity_query_size or adding pg_stat_statements, or even
wildly long search_paths).

This also covers some of the more esoteric use cases, such as wanting
to "turn off" indexes for mixed workload replica trees, and covers the
often mentioned use case of allowing an index to be created
"invisible" by default (just add the proposed index name to the list
before creation).

And I'll also mention that this seems like the method least likely to
conflict with an ALTER INDEX implementation if we want to add one down
the line (I think there is an argument for it), since I imagine that
you could create such a thing with a boolean catalog flag that mimics
the gucs behavior, so that the GUC or catalog aren't trying to
override each other. Of course I'm tempted to say you could maybe
implement this like an index storage parameter, but that might be a
bridge too far... still if we make the GUC first, that would certainly
be an interesting idea to explore.

1) /messages/by-id/15238d97-f667-48df-8319-ab73b37d4511@eisentraut.org
2) /messages/by-id/3465209.1727202064@sss.pgh.pa.us

Robert Treat
https://xzilla.net

#120Sami Imseih
samimseih@gmail.com
In reply to: Robert Treat (#119)
Re: [PATCH] Proposal to Enable/Disable Index using ALTER INDEX

it will still be extremely risky in
heavy production workloads. In short, we're both walking a bull
through the china shop, but it would seem mine is much more
temperamental than yours.

Robert, Could you describe the GUC you would like to see?

Also, I'd like to ask. what would be the argument against offering both options,
ALTER and a GUC to override the catalog, as currently proposed in the patch?

This conversation has been mainly GUC is better than ALTER, or vice versa.

It is clear, at least to me, there are merits in both approaches, so
what would be
the argument against making both options available ( maybe with a GUC that
could be more useful than a simple boolean )?

Just to reiterate, I am not against having both a GUC and ALTER
option, if implemented correctly.

Thanks. This got lost, at least to me, in the thread above.

Like David, I don't have good
feelings about the ALTER / use_invisible_index GUC overwriting
behavior that is explicitly written in the catalog,

OK, although I don't necessarily think this is something to be frowned
upon. I mean, if we end up with an ALTER/GUC combo, I can't see
how we can avoid such behavior.

and I see no
reason to settle for a technically awkward solution when I think it
also delivers a poor user interface that will be hard to reason about
and/or debug in production.

This is already an established pattern has been used by other
RDBMS's. Having worked with such interface in the past, a combo of
ALTER and GUC, I never thought it was awkward and it's quite simple to
understand/maintain. But that is subjective.

So I think the "right" interface looks something like a GUC that would
be something like "ignore_index_planning" which takes a csv list of
index names that the planner would ignore.

A few years back, I explored this idea, and I did not really like the parsing
overhead for every execution. You will need to supply a list of fully-qualified
( dbname.schemaname.indexname) names or carefully manage the GUC
per database. Also, if you drop an index, you now must go cleanup the list,
and especially if at some point you recreate the index with the same name.
There is also that you have to push this GUC to all your standbys manually.

This never sounded good to me as a core feature, or do I think it's a really
friendly interface, and I think you can get in more trouble trying to deal with
such a GUC that requires such management.

--
Sami

#121Robert Treat
rob@xzilla.net
In reply to: Sami Imseih (#120)
Re: [PATCH] Proposal to Enable/Disable Index using ALTER INDEX

On Mon, Jul 21, 2025 at 5:24 PM Sami Imseih <samimseih@gmail.com> wrote:

it will still be extremely risky in
heavy production workloads. In short, we're both walking a bull
through the china shop, but it would seem mine is much more
temperamental than yours.

Robert, Could you describe the GUC you would like to see?

Also, I'd like to ask. what would be the argument against offering both options,
ALTER and a GUC to override the catalog, as currently proposed in the patch?

This conversation has been mainly GUC is better than ALTER, or vice versa.

It is clear, at least to me, there are merits in both approaches, so
what would be
the argument against making both options available ( maybe with a GUC that
could be more useful than a simple boolean )?

Just to reiterate, I am not against having both a GUC and ALTER
option, if implemented correctly.

Thanks. This got lost, at least to me, in the thread above.

Like David, I don't have good
feelings about the ALTER / use_invisible_index GUC overwriting
behavior that is explicitly written in the catalog,

OK, although I don't necessarily think this is something to be frowned
upon. I mean, if we end up with an ALTER/GUC combo, I can't see
how we can avoid such behavior.

I laid out two potential options in my previous email; if we implement
this like a storage option, then you are setting the guc at the index
level, which would resolve any opposing behavior. Even if you didn't
do that, if the catalog only indicates that index should be ignored,
rather than trying to control yes/no of index ignoring, then there is
no conflict. If the flag says ignore, you ignore. If the GUC says
ignore, you ignore. If you don't find either, you don't ignore
(default).

and I see no
reason to settle for a technically awkward solution when I think it
also delivers a poor user interface that will be hard to reason about
and/or debug in production.

This is already an established pattern has been used by other
RDBMS's. Having worked with such interface in the past, a combo of
ALTER and GUC, I never thought it was awkward and it's quite simple to
understand/maintain. But that is subjective.

It's amazing what people are willing to put up with if they are first
conditioned to believe it is the right way :-)

What stands out to me in the Oracle implementation is that they don't
sell it as a way to safely verify that indexes are unused before
dropping, but that it provides a way to safely create an index without
it being used. Both use cases are valid, but the former certainly
seems like the far more desired feature, and yet they seem to shy away
from showing the extra hoop jumping to make that work, I think
precisely because it is awkward to work with. I think we should try to
make the most common use case easier.

So I think the "right" interface looks something like a GUC that would
be something like "ignore_index_planning" which takes a csv list of
index names that the planner would ignore.

A few years back, I explored this idea, and I did not really like the parsing
overhead for every execution. You will need to supply a list of fully-qualified
( dbname.schemaname.indexname) names or carefully manage the GUC
per database.

I think I'd agree that you may need to be careful, but that's true of
most things. I'm less sure of the need to use fully qualified names;
pg_hint_plan does not have that restriction, and arguably there are
use cases against wanting to do that (imagine a multi-tenant scenario
where you want a specific role to ignore an index regardless of which
database it connects to, as all databases have the same schema).

Also, if you drop an index, you now must go cleanup the list,
and especially if at some point you recreate the index with the same name.
There is also that you have to push this GUC to all your standbys manually.

This never sounded good to me as a core feature, or do I think it's a really
friendly interface, and I think you can get in more trouble trying to deal with
such a GUC that requires such management.

It isn't clear to me which option you are speaking about here. If you
believe you need a GUC (which you have said up-thread), then there is
going to be some GUC management for any such implementation. If you
set a role with a boolean "ignore_disabled_indexes" because you are
dropping an index, you'll certainly want to clean that up once the
index is dropped. There might be more bookkeeping for the DBA with a
csv list, but only because it allows the DBA more flexibility in how
it is implemented. If you stick to managing one index at a time, the
bookkeeping is basically the same.

Robert Treat
https://xzilla.net

#122Sami Imseih
samimseih@gmail.com
In reply to: Robert Treat (#121)
Re: [PATCH] Proposal to Enable/Disable Index using ALTER INDEX

This is already an established pattern has been used by other
RDBMS's. Having worked with such interface in the past, a combo of
ALTER and GUC, I never thought it was awkward and it's quite simple to
understand/maintain. But that is subjective.

It's amazing what people are willing to put up with if they are first
conditioned to believe it is the right way :-)

Well, it works and serves its purpose (or even multiple purposes).

Also, whichever direction we go in will ultimately become the method
our users adopt. That’s just how these things work.

So, I respectfully disagree with your view :)

What stands out to me in the Oracle implementation is that they don't
sell it as a way to safely verify that indexes are unused before
dropping, but that it provides a way to safely create an index without
it being used.

Ultimately, the ALTER command guarantees that the index is not being used,
since it applies a global change.

The GUC serves multiple purposes. For example,I can create an index as invisible
and use it in a controlled way, which is helpful for experimenting
with a new index.
I can also make an index visible only to certain workloads, let's say
the replicas only.
Also, If part of my workload suffers because I made the index is
invisible, I can selectively
make the index visible again using this GUC whileI figure things out.
In that case, it acts as a
safety measure against the global change, without having to roll it
back everywhere.
I think it’s quite versatile in its application.

Both use cases are valid, but the former certainly
seems like the far more desired feature, and yet they seem to shy away
from showing the extra hoop jumping to make that work

I'm not following your point about how it's awkward.

So I think the "right" interface looks something like a GUC that would
be something like "ignore_index_planning" which takes a csv list of
index names that the planner would ignore.

A few years back, I explored this idea, and I did not really like the parsing
overhead for every execution. You will need to supply a list of fully-qualified
( dbname.schemaname.indexname) names or carefully manage the GUC
per database.

I think I'd agree that you may need to be careful, but that's true of
most things. I'm less sure of the need to use fully qualified names;
pg_hint_plan does not have that restriction,

pg_hint_plan works at the query level, and the hints are resolved based on
aliases, if I recall correctly. This is quite different from a GUC, which can
be applied at multiple levels, including the cluster level.

There might be more bookkeeping for the DBA with a
csv list, but only because it allows the DBA more flexibility in how
it is implemented. If you stick to managing one index at a time, the
bookkeeping is basically the same.

Sure, that's a fair point, and I don't disagree with the flexibility that such
a GUC provides. As I said, when I first started thinking about this problem,
I found the flexibility of a list-based GUC to be desirable, but I couldn't
rationalize the performance and maintenance trade-offs it incurs.

I'm definitely open to having my mind changed again on this topic. But I
don’t see this GUC as an opposing feature to the ALTER command, which I
still believe we should have.

In my view, the real question we are now debating is about how we
should implement the GUC.

--
Sami

#123David Rowley
dgrowleyml@gmail.com
In reply to: Sami Imseih (#118)
Re: [PATCH] Proposal to Enable/Disable Index using ALTER INDEX

On Tue, 22 Jul 2025 at 05:16, Sami Imseih <samimseih@gmail.com> wrote:

Also, I'd like to ask. what would be the argument against offering both options,
ALTER and a GUC to override the catalog, as currently proposed in the patch?

For me, the reason I don't like ALTER TABLE + the use_invisible_index
/ force_invisible_index (the v18 patch seems to be confused about the
name of that GUC) is because it puts into question what "invisible"
means. It's going to be a pretty useless feature for use cases where a
DBA wants to ensure a certain index is *never* used, but does not want
to drop it. A DBA might want to disable a certain index to investigate
certain forms of index corruption and it might not be good if people
can just overwrite that to bypass the DBA's choice.

It might be a slightly more flexible feature if there were 3 possible
states and one of those states could be clearly defined to mean that
users can overwrite the disabledness of all indexes by setting a GUC.
I'm still struggling to like that, however.

Now wondering if it would be better to spend the effort looking at
pg_hint_plan and seeing how hard it would be to get global hints added
which are applied to all queries, and then add a way to disable use of
a named index. (I don't have any experience with that extension other
than looking at the documentation)

David

#124Sami Imseih
samimseih@gmail.com
In reply to: David Rowley (#123)
Re: [PATCH] Proposal to Enable/Disable Index using ALTER INDEX

Now wondering if it would be better to spend the effort looking at
pg_hint_plan and seeing how hard it would be to get global hints added
which are applied to all queries, and then add a way to disable use of
a named index. (I don't have any experience with that extension other
than looking at the documentation)

Regardless of what comes out of this thread, pg_hint_plan supporting
a NoIndexScan hint that takes in an index name, and not only a relname
is needed. I plan on taking that up there.

--

Sami

#125Robert Treat
rob@xzilla.net
In reply to: David Rowley (#123)
Re: [PATCH] Proposal to Enable/Disable Index using ALTER INDEX

On Tue, Jul 22, 2025 at 6:50 PM David Rowley <dgrowleyml@gmail.com> wrote:

On Tue, 22 Jul 2025 at 05:16, Sami Imseih <samimseih@gmail.com> wrote:

Also, I'd like to ask. what would be the argument against offering both options,
ALTER and a GUC to override the catalog, as currently proposed in the patch?

For me, the reason I don't like ALTER TABLE + the use_invisible_index
/ force_invisible_index (the v18 patch seems to be confused about the
name of that GUC) is because it puts into question what "invisible"
means. It's going to be a pretty useless feature for use cases where a
DBA wants to ensure a certain index is *never* used, but does not want
to drop it. A DBA might want to disable a certain index to investigate
certain forms of index corruption and it might not be good if people
can just overwrite that to bypass the DBA's choice.

Thanks for elaborating on this, you said it better than me.

So I'll note that in my proposal, the hypothetical catalog update
("alter index set guc" or whatever) is a one way door; if the dba (or
whomever) sets that, then the index is ignored everywhere, since the
session level guc can only also suggest the index be ignored from
planning. That is enough to allow people to both slow roll out OR slow
roll in new indexes, as needed, which I think covers enough ground
without the complexity going too far (which your below example clearly
shows is possible).

It might be a slightly more flexible feature if there were 3 possible
states and one of those states could be clearly defined to mean that
users can overwrite the disabledness of all indexes by setting a GUC.
I'm still struggling to like that, however.

Now wondering if it would be better to spend the effort looking at
pg_hint_plan and seeing how hard it would be to get global hints added
which are applied to all queries, and then add a way to disable use of
a named index. (I don't have any experience with that extension other
than looking at the documentation)

I'd be interested in your evaluation of this, but the GUC I've
outlined would accomplish most of the use cases here automagically.

Robert Treat
https://xzilla.net

#126Michael Paquier
michael@paquier.xyz
In reply to: Sami Imseih (#124)
Re: [PATCH] Proposal to Enable/Disable Index using ALTER INDEX

On Tue, Jul 22, 2025 at 06:04:50PM -0500, Sami Imseih wrote:

Regardless of what comes out of this thread, pg_hint_plan supporting
a NoIndexScan hint that takes in an index name, and not only a relname
is needed. I plan on taking that up there.

Patches are welcome upstream.
--
Michael

#127Michael Paquier
michael@paquier.xyz
In reply to: Sami Imseih (#122)
Re: [PATCH] Proposal to Enable/Disable Index using ALTER INDEX

On Tue, Jul 22, 2025 at 01:15:16PM -0500, Sami Imseih wrote:

The GUC serves multiple purposes. For example,I can create an index as invisible
and use it in a controlled way, which is helpful for experimenting
with a new index.

An in-core GUC to control the list of indexes that should be allowed
or disallowed is I think asking for trouble, adding schema-related
knowledge directly into the GUC machinery. This does not scale well,
even if you force all the entries to be specified down to the database
and the schema. And it makes harder to control what a "good" behavior
should be at query-level.

My 2c.
--
Michael

#128Shayon Mukherjee
shayonj@gmail.com
In reply to: Robert Treat (#111)
Re: [PATCH] Proposal to Enable/Disable Index using ALTER INDEX

On Jul 15, 2025, at 1:58 PM, Robert Treat <rob@xzilla.net> wrote:

On Tue, Jul 15, 2025 at 8:19 AM Shayon Mukherjee <shayonj@gmail.com> wrote:

On Jun 23, 2025, at 10:14 AM, Robert Treat <rob@xzilla.net> wrote:
Glad to hear you are still interested, slightly disheartened by the
general lack of concern around operational safety in this thread. I
actually think what you have done covers a lot of the ground for
multiple implementations, so I'm optimistic we can get something for
19.

Just for my own learning and mental model - what would be a good way to understand the change that wasn’t operationally safe?

Generally speaking, the two biggest factors for operational safety are
the ability to slowly ramp up changes in a controlled fashion, and
conversely the ability to quickly reverse them. On its surface, the
ALTER feature looks like it passes both of these tests because (in
simple cases) it appears better than drop/create index process alone;
indeed, the ability to "turn off" an index before dropping it feels
like a slower roll out than dropping it, and the ability to "turn it
back on" seems like a much quicker reversal than having to recreate
the index. Our problem is that this only gives the appearance of
safety without having provided any significant improvement in system
safety, especially in more complex and/or demanding setups. With
regards to roll out specifically, the ALTER method is no safer than
drop index because both use DDL which means they are both open to
blocking or being blocked by conflicting queries, which increase
operational risk within the system. Similarly, the nature of the DDL
change also requires that all sessions be impacted everywhere at once;
there is no way to slowly roll the change to some segment of the
database or some specific workload within the system. So it fails the
first test. With regards to the ability to quickly reverse the change,
it does beat the need to rebuild an index, but that only helps in a
very small subset of the typical use cases for this feature; ie where
you are concerned that your server might get "swamped" by poorly
performing queries while the index rebuilds. But that's a pretty low
level version of the problem; on very busy systems and/or system with
delicately balanced buffer caching, even a small pause measured in
seconds could be enough to bring a system down, and again our use of
DDL opens us up to delays from conflicting queries, untimely
wraparound vacuums, concurrent WAL traffic in the case of wanting to
do this across replica trees (which you can't not do). So we generally
fail the second test for a large portion of the use cases involved.
And maybe that would be ok if we didn't have a way to solve this
problem that doesn't fail these tests, but we do, which is through
using a GUC.

I was thinking about this some more over the weekend and it does seem
like you can't get away from doing something with DDL; even though it
is the wrong mental model... like when your AC is running but you
don't think it is cool enough, so you turn it down farther, as if it
would blow colder air... but that isn't how AC actually work... it
seems you can't eliminate the desire for this mental model entirely.
Which to be clear, I am not against, it's just a bad tool for the hard
cases, but not in every case. Anyway, if I were picking this up, I
would separate out the two ideas; as I laid out in my email to David,
the GUC solution can stand on it's own without the DDL implementation,
and I would do that first, and then add a simplified DDL
implementation after the fact. Of course it could be done the other
way around, but I think you're more likely to land on the correct GUC
implementation if it isn't mixed up with DDL, and the best way to
assure that is by not having the DDL for the initial patch. Just my
.02, but happy to help spec it out further.

I am happy to split this into two, however I think starting with GUC first may not achieve a lot of cases that David and I were talking about earlier in the thread, perhaps? Where, if you want quick feedback without needing to make application / session / connection level changes (i.e GUC) then you can quickly do it via the ALTER statement. Happy to redo the patch and just keep ALTER for v1 accordingly, if it still makes sense.

I think it is much more the other way around; the GUC handles far more
of the potential use cases that you might want to use the ALTER for,
and the ALTER clearly falls short of what the GUC can do. (Side note,
remember you can modify the GUC at the database level. And if you
really want to get ambitious, GUCs can be extended to work through
ALTER TABLE).

Would folks have any preference between the two approaches?

Contrary to how it sounds, I'm not actually opposed to having both :-)
But I am very concerned that an implementation which does ALTER first
sets a sort of anchoring bias that would affect how the GUC feature
gets implemented, which is how I suspect Oracle ended up with their
crappy implementation. I don't think this happens in reverse; ie. the
GUC first implementation handles most of the heavy lifting so the
ALTER only needs to cover the suite spot of the use cases that it can
actually help with.

I know the thread has gotten quite long and I'm a little late to the party, but thank you for taking the time to walk me through the operational safety considerations you were referencing. I have a much better mental model of what you mean now.

Just like David mentioned earlier in this thread, I was approaching this problem from the perspective of being 99% certain the index isn't used, and thinking that a DDL to enable/disable indexes without needing a rebuild would be useful. However, I understand your point that not everyone may approach using the DDL in the same way, or may not have done their due diligence, which could negatively impact busy systems. Though I think that's partly the responsibility of the DBA/developer as well - for example, we have `pg_stat_user_indexes`, and I'd typically use the stats in that table to understand index usage before trying to disable it. At the same time, I do agree with your point about making common workflows easy and safe for users. There is def something there.

The whole thread has made it very clear that there are pros and cons to all the approaches mentioned so far, and I'll refrain from extending this tangent any further :D. I'll reply on the main thread with some thoughts additional thoughts. I just wanted to express my appreciation for you taking the time to walk me through your perspective in more depth.

P.S. I think we're approaching the 11-month anniversary of this thread (started on September 9, 2024, by yours truly) and I am very humbled, and impressed by the community's rigor here :). I personally would love to see something land in core, and I'm confident we'll get there.

Thanks
Shayon

#129Shayon Mukherjee
shayonj@gmail.com
In reply to: Michael Paquier (#127)
Re: [PATCH] Proposal to Enable/Disable Index using ALTER INDEX

Hello,

On Jul 23, 2025, at 9:43 PM, Michael Paquier <michael@paquier.xyz> wrote:

On Tue, Jul 22, 2025 at 01:15:16PM -0500, Sami Imseih wrote:

The GUC serves multiple purposes. For example,I can create an index as invisible
and use it in a controlled way, which is helpful for experimenting
with a new index.

An in-core GUC to control the list of indexes that should be allowed
or disallowed is I think asking for trouble, adding schema-related
knowledge directly into the GUC machinery. This does not scale well,
even if you force all the entries to be specified down to the database
and the schema. And it makes harder to control what a "good" behavior
should be at query-level.

My 2c.

+1

I wonder if there's a path to simplify things further here while still providing a way to gradually build confidence when disabling and then dropping an index. As a developer/DBA or person in a similar position, I think my journey for dropping an index in this new world would look something like this:

1. Research phase: Use `pg_stat_user_indexes`, query analysis to understand index usage
2. Experimentation phase: Use `pg_hint_plan` (or GUC?) for session-level testing and slower rollout from applications using feature flags
- Up until a while ago, this step won't exist because once I had enough confidence from step 1, I'd go to step 3. Which is a huge improvement from jumping to Step 4 below. But the new discussions have made me think that this step is important.
3. Validation phase: Use `ALTER INDEX INVISIBLE` for final system-wide confidence building
4. Cleanup phase: `DROP INDEX` when certain

Per this plan, this would mean that pg_hint_plan would need to support index-level hints, and it’s not a massive / impossible task. But it also means that both systems aren't fighting/overriding each other or making it difficult for users to understand when exactly an index is being used or not. Ultimately, this would also mean that `ALTER INDEX INVISIBLE` is a one-way door, and there is only one way to control index visibility in core, which makes sense to me.

I think any pitfalls and guarantees can be communicated well through documentation both in core and in `pg_hint_plan`. What’s not clear to me here is, how common / intuitive of a workflow will this be and if it fits easily in the “common use case” path?

There are some aspects of the GUC approach that I'd miss, also because as a developer I've used DDLs and GUCs more than pg_hint_plan, but it's probably just a tooling exposure thing perhaps.

Curious what folks think.

P.S. Still very happy to help with patches whenever that is.

Thanks,
Shayon

#130Michael Paquier
michael@paquier.xyz
In reply to: Shayon Mukherjee (#129)
Re: [PATCH] Proposal to Enable/Disable Index using ALTER INDEX

On Sat, Aug 02, 2025 at 03:09:19PM -0400, Shayon Mukherjee wrote:

Per this plan, this would mean that pg_hint_plan would need to
support index-level hints, and it’s not a massive / impossible
task. But it also means that both systems aren't fighting/overriding
each other or making it difficult for users to understand when
exactly an index is being used or not. Ultimately, this would also
mean that `ALTER INDEX INVISIBLE` is a one-way door, and there is
only one way to control index visibility in core, which makes sense
to me.

Sami has proposed a patch for pg_hint_plan that goes in the direction
of a DisableIndex hint, which is doable even if it requires some work
inside the extension code like some refactoring:
https://github.com/ossc-db/pg_hint_plan/issues/226

So I cannot say much about this proposal for core, but for
pg_hint_plan I'm looking at adding that for the v18 release of the
module, which is planned for the end of August/beginning of September.
--
Michael

#131Julien Rouhaud
rjuju123@gmail.com
In reply to: Michael Paquier (#130)
Re: [PATCH] Proposal to Enable/Disable Index using ALTER INDEX

On Mon, Aug 04, 2025 at 01:19:46PM +0900, Michael Paquier wrote:

On Sat, Aug 02, 2025 at 03:09:19PM -0400, Shayon Mukherjee wrote:

Per this plan, this would mean that pg_hint_plan would need to
support index-level hints, and it’s not a massive / impossible
task. But it also means that both systems aren't fighting/overriding
each other or making it difficult for users to understand when
exactly an index is being used or not. Ultimately, this would also
mean that `ALTER INDEX INVISIBLE` is a one-way door, and there is
only one way to control index visibility in core, which makes sense
to me.

Sami has proposed a patch for pg_hint_plan that goes in the direction
of a DisableIndex hint, which is doable even if it requires some work
inside the extension code like some refactoring:
https://github.com/ossc-db/pg_hint_plan/issues/226

So I cannot say much about this proposal for core, but for
pg_hint_plan I'm looking at adding that for the v18 release of the
module, which is planned for the end of August/beginning of September.

FWIW if anyone actually needs it, that feature had existed for decades in
plantuner: http://www.sigaev.ru/git/gitweb.cgi?p=plantuner.git;a=summary

#132Michael Paquier
michael@paquier.xyz
In reply to: Julien Rouhaud (#131)
Re: [PATCH] Proposal to Enable/Disable Index using ALTER INDEX

On Mon, Aug 04, 2025 at 12:34:14PM +0800, Julien Rouhaud wrote:

FWIW if anyone actually needs it, that feature had existed for decades in
plantuner: http://www.sigaev.ru/git/gitweb.cgi?p=plantuner.git;a=summary

Your link does not work here, this one does:
https://github.com/postgrespro/plantuner

Thanks for mentioning that, so it's a set of GUCs that rely on
get_relation_info_hook_type for the index filtering.
--
Michael

#133Julien Rouhaud
rjuju123@gmail.com
In reply to: Michael Paquier (#132)
Re: [PATCH] Proposal to Enable/Disable Index using ALTER INDEX

On Mon, 4 Aug 2025, 12:39 Michael Paquier, <michael@paquier.xyz> wrote:

On Mon, Aug 04, 2025 at 12:34:14PM +0800, Julien Rouhaud wrote:

FWIW if anyone actually needs it, that feature had existed for decades in
plantuner: http://www.sigaev.ru/git/gitweb.cgi?p=plantuner.git;a=summary

that's weird, I tried from 2 different ISP in Taiwan and both work just
fine, I guess Japan is blocking .ru tld.

Your link does not work here, this one does:
https://github.com/postgrespro/plantuner

yes although this one doesn't seem maintained anymore, the original repo
does have way more recent commits.

Thanks for mentioning that, so it's a set of GUCs that rely on
get_relation_info_hook_type for the index filtering.

exactly.

Show quoted text
#134Michael Paquier
michael@paquier.xyz
In reply to: Michael Paquier (#130)
Re: [PATCH] Proposal to Enable/Disable Index using ALTER INDEX

On Mon, Aug 04, 2025 at 01:19:46PM +0900, Michael Paquier wrote:

Sami has proposed a patch for pg_hint_plan that goes in the direction
of a DisableIndex hint, which is doable even if it requires some work
inside the extension code like some refactoring:
https://github.com/ossc-db/pg_hint_plan/issues/226

So I cannot say much about this proposal for core, but for
pg_hint_plan I'm looking at adding that for the v18 release of the
module, which is planned for the end of August/beginning of September.

FWIW, I have been able to merge the patch to add support for this
DisableIndex hint in pg_hint_plan. So at least this will give people
something to toy with even without this in-core feature. That will be
included in next week's release, available in the version of the
module compatible with v18.
--
Michael

#135Shayon Mukherjee
shayonj@gmail.com
In reply to: Michael Paquier (#134)
Re: [PATCH] Proposal to Enable/Disable Index using ALTER INDEX

Hello Hackers,

Looks like there may not be enough interest to port any functionality into core. So, just noting that I have withdrawn the patch from CommitFest[1]https://commitfest.postgresql.org/patch/5274/. Thank you for the good discussions and leanings.

[1]: https://commitfest.postgresql.org/patch/5274/

Shayon

Show quoted text

On Aug 11, 2025, at 6:22 AM, Michael Paquier <michael@paquier.xyz> wrote:

On Mon, Aug 04, 2025 at 01:19:46PM +0900, Michael Paquier wrote:

Sami has proposed a patch for pg_hint_plan that goes in the direction
of a DisableIndex hint, which is doable even if it requires some work
inside the extension code like some refactoring:
https://github.com/ossc-db/pg_hint_plan/issues/226

So I cannot say much about this proposal for core, but for
pg_hint_plan I'm looking at adding that for the v18 release of the
module, which is planned for the end of August/beginning of September.

FWIW, I have been able to merge the patch to add support for this
DisableIndex hint in pg_hint_plan. So at least this will give people
something to toy with even without this in-core feature. That will be
included in next week's release, available in the version of the
module compatible with v18.
--
Michael

#136Robert Treat
rob@xzilla.net
In reply to: Shayon Mukherjee (#135)
Re: [PATCH] Proposal to Enable/Disable Index using ALTER INDEX

On Mon, Sep 8, 2025 at 1:15 PM Shayon Mukherjee <shayonj@gmail.com> wrote:

Hello Hackers,

Looks like there may not be enough interest to port any functionality into
core. So, just noting that I have withdrawn the patch from CommitFest[1].
Thank you for the good discussions and leanings.

Thanks for your work on this. For those who may not be aware, Sami did

implement a version of this in pg_hint_plan{1}, so that is helpful. I think
it may be worth revisiting this in core, but perhaps once we seen this new
implementation in action for a bit. (?)

{1}
https://github.com/ossc-db/pg_hint_plan/commit/d2cfd2f2c1fd18f55123b12c2250a384ccfaefaf

Robert Treat
https://xzilla.net

#137Michael Paquier
michael@paquier.xyz
In reply to: Robert Treat (#136)
Re: [PATCH] Proposal to Enable/Disable Index using ALTER INDEX

On Mon, Sep 08, 2025 at 09:37:39AM -0400, Robert Treat wrote:

Thanks for your work on this. For those who may not be aware, Sami did
implement a version of this in pg_hint_plan{1}, so that is helpful. I think
it may be worth revisiting this in core, but perhaps once we seen this new
implementation in action for a bit. (?)

{1}
https://github.com/ossc-db/pg_hint_plan/commit/d2cfd2f2c1fd18f55123b12c2250a384ccfaefaf

A side note on this one: it may make sense to implement regexp
handling in this new hint, where all the indexes matching the regexp
become ignored by the planner. We have not done that because we
wanted to see the impact of the initial feature first. I don't think
that this would increase the complexity footprint by a lot.
--
Michael