Skip to content

Commit

Permalink
Add support for hypothetically hide existing index on explain.
Browse files Browse the repository at this point in the history
Add new list hideIndexes and develop new function by hypo_get_relation_info_hook.
User can hide or unhide existing index and hypothetical indexes.
When user set hide existing index and execute EXPLAIN, it will scan the same oid in hideIndexes and remove it to make query-plan can't use it.
Add regression tests for hiding existing indexes.
Update to version hypopg--1.4.0.
Provide simple examples of using the hide series functions in README.md.
Update doc about hypothetically hide existing indexes.
  • Loading branch information
nutVI authored and rjuju committed Mar 23, 2023
1 parent 93f15d0 commit 351f14a
Show file tree
Hide file tree
Showing 11 changed files with 910 additions and 0 deletions.
1 change: 1 addition & 0 deletions CONTRIBUTORS.md
Original file line number Diff line number Diff line change
Expand Up @@ -19,3 +19,4 @@ People who contributed to hypopg:
* github user nikhil-postgres
* Xiaozhe Yao
* Krzysztof Szularz
* NutVII
2 changes: 2 additions & 0 deletions Makefile
Original file line number Diff line number Diff line change
Expand Up @@ -51,6 +51,8 @@ ifneq ($(MAJORVERSION),$(filter $(MAJORVERSION), 9.2 9.3 9.4 9.5 9.6))
REGRESS += hypo_hash
endif

REGRESS += hypo_hide_index

DEBUILD_ROOT = /tmp/$(EXTENSION)

deb: release-zip
Expand Down
85 changes: 85 additions & 0 deletions README.md
Original file line number Diff line number Diff line change
Expand Up @@ -99,3 +99,88 @@ To remove your backend's hypothetical indexes, you can use the function
`hypopg_drop_index(indexrelid)` with the OID that the `hypopg_list_indexes`
view returns and call `hypopg_reset()` to remove all at once, or just close
your current connection.

Continuing with the above case, you can `hide existing indexes`,
but should be use `hypopg_reset()` to clear the previous effects of other indexes at first.

Create two real indexes and run `EXPLAIN`:

rjuju=# SELECT hypopg_reset();
rjuju=# CREATE INDEX ON hypo(id);
rjuju=# CREATE INDEX ON hypo(id, val);
rjuju=# EXPLAIN SELECT * FROM hypo WHERE id = 1;
QUERY PLAN
----------------------------------------------------------------------------------
Index Only Scan using hypo_id_val_idx on hypo (cost=0.29..8.30 rows=1 width=13)
Index Cond: (id = 1)
(2 rows)

The query plan is using the `hypo_id_val_idx` index. Use `hypopg_hide_index(oid)` to hide one of the indexes:

rjuju=# SELECT hypopg_hide_index('hypo_id_val_idx'::REGCLASS);
rjuju=# EXPLAIN SELECT * FROM hypo WHERE id = 1;
QUERY PLAN
-------------------------------------------------------------------------
Index Scan using hypo_id_idx on hypo (cost=0.29..8.30 rows=1 width=13)
Index Cond: (id = 1)
(2 rows)

The query plan is using the other index `hypo_id_idx` now. Use `hypopg_hide_index(oid)` to hide it:

rjuju=# SELECT hypopg_hide_index('hypo_id_idx'::REGCLASS);
rjuju=# EXPLAIN SELECT * FROM hypo WHERE id = 1;
QUERY PLAN
-------------------------------------------------------
Seq Scan on hypo (cost=0.00..180.00 rows=1 width=13)
Filter: (id = 1)
(2 rows)

And now the query plan changes back to `Seq Scan`. Use `hypopg_unhide_index(oid)` to restore index:

rjuju=# SELECT hypopg_unhide_index('hypo_id_idx'::regclass);
rjuju=# EXPLAIN SELECT * FROM hypo WHERE id = 1;
QUERY PLAN
-------------------------------------------------------------------------
Index Scan using hypo_id_idx on hypo (cost=0.29..8.30 rows=1 width=13)
Index Cond: (id = 1)
(2 rows)

Of course, you can also hide hypothetical indexes:

rjuju=# SELECT hypopg_create_index('CREATE INDEX ON hypo(id)');
rjuju=# EXPLAIN SELECT * FROM hypo WHERE id = 1;
QUERY PLAN
------------------------------------------------------------------------------------
Index Scan using "<12659>btree_hypo_id" on hypo (cost=0.04..8.05 rows=1 width=13)
Index Cond: (id = 1)
(2 rows)

rjuju=# SELECT hypopg_hide_index(12659);
rjuju=# EXPLAIN SELECT * FROM hypo WHERE id = 1;
QUERY PLAN
-------------------------------------------------------
Seq Scan on hypo (cost=0.00..180.00 rows=1 width=13)
Filter: (id = 1)
(2 rows)

You can check which indexes are hidden using `hypopg_hidden_indexes()` or the `hypopg_hidden_indexes` view:

rjuju=# SELECT * FROM hypopg_hidden_indexes();
indexid
---------
526604
526603
12659
(3 rows)

rjuju=# SELECT * FROM hypopg_hidden_indexes;
indexrelid | index_name | schema_name | table_name | am_name | is_hypo
------------+----------------------+-------------+------------+---------+---------
12659 | <12659>btree_hypo_id | public | hypo | btree | t
526603 | hypo_id_idx | public | hypo | btree | f
526604 | hypo_id_val_idx | public | hypo | btree | f
(3 rows)

To restore all existing indexes, you can use the function `hypopg_unhide_all_indexes()`.
Note that the functionality to hide existing indexes only applies to the EXPLAIN command in the current session
and will not affect other sessions.
166 changes: 166 additions & 0 deletions docs/usage.rst
Original file line number Diff line number Diff line change
Expand Up @@ -224,3 +224,169 @@ Some other convenience functions and views are available:
- **hypopg_drop_index(oid)**: function that removes the given hypothetical
index
- **hypopg_reset()**: function that removes all hypothetical indexes

Hypothetically hide existing indexes
------------------------------------

You can hide both existing and hypothetical indexes hypothetically.
If you want to test it as described in the documentation,
you should first use **hypopg_reset()** to clear the effects of any other hypothetical indexes.

As a simple case, let's consider two indexes:

.. code-block:: psql
SELECT hypopg_reset();
CREATE INDEX ON hypo(id);
CREATE INDEX ON hypo(id, val);
.. code-block:: psql
:emphasize-lines: 4
EXPLAIN SELECT * FROM hypo WHERE id = 1;
QUERY PLAN
----------------------------------------------------------------------------------
Index Only Scan using hypo_id_val_idx on hypo (cost=0.29..8.30 rows=1 width=13)
Index Cond: (id = 1)
(2 rows)
The query plan is using the **hypo_id_val_idx** index now.

- **hypopg_hide_index(oid)**: function that allows you to hide an index in the EXPLAIN output by using its OID.
It returns `true` if the index was successfully hidden, and `false` otherwise.

.. code-block:: psql
:emphasize-lines: 10
SELECT hypopg_hide_index('hypo_id_val_idx'::REGCLASS);
hypopg_hide_index
-------------------
t
(1 row)
EXPLAIN SELECT * FROM hypo WHERE id = 1;
QUERY PLAN
-------------------------------------------------------------------------
Index Scan using hypo_id_idx on hypo (cost=0.29..8.30 rows=1 width=13)
Index Cond: (id = 1)
(2 rows)
As an example, let's assume that the query plan is currently using the **hypo_id_val_idx** index.
To continue testing, use the **hypopg_hide_index(oid)** function to hide another index.

.. code-block:: psql
:emphasize-lines: 10
SELECT hypopg_hide_index('hypo_id_idx'::REGCLASS);
hypopg_hide_index
-------------------
t
(1 row)
EXPLAIN SELECT * FROM hypo WHERE id = 1;
QUERY PLAN
-------------------------------------------------------
Seq Scan on hypo (cost=0.00..180.00 rows=1 width=13)
Filter: (id = 1)
(2 rows)
- **hypopg_unhide_index(oid)**: function that restore a previously hidden index in the EXPLAIN output by using its OID.
It returns `true` if the index was successfully restored, and `false` otherwise.

.. code-block:: psql
:emphasize-lines: 10
SELECT hypopg_unhide_index('hypo_id_idx'::regclass);
hypopg_unhide_index
-------------------
t
(1 row)
EXPLAIN SELECT * FROM hypo WHERE id = 1;
QUERY PLAN
-------------------------------------------------------------------------
Index Scan using hypo_id_idx on hypo (cost=0.29..8.30 rows=1 width=13)
Index Cond: (id = 1)
(2 rows)
- **hypopg_unhide_all_index()**: function that restore all hidden indexes and returns void.

- **hypopg_hidden_indexes()**: function that returns a list of OIDs for all hidden indexes.

.. code-block:: psql
SELECT * FROM hypopg_hidden_indexes();
indexid
---------
526604
(1 rows)
- **hypopg_hidden_indexes**: view that returns a formatted list of all hidden indexes.

.. code-block:: psql
SELECT * FROM hypopg_hidden_indexes;
indexrelid | index_name | schema_name | table_name | am_name | is_hypo
-------------+----------------------+-------------+------------+---------+---------
526604 | hypo_id_val_idx | public | hypo | btree | f
(1 rows)
.. note::

Hypothetical indexes can be hidden as well.

.. code-block:: psql
:emphasize-lines: 10
SELECT hypopg_create_index('CREATE INDEX ON hypo(id)');
hypopg_create_index
------------------------------
(12659,<12659>btree_hypo_id)
(1 row)
EXPLAIN SELECT * FROM hypo WHERE id = 1;
QUERY PLAN
------------------------------------------------------------------------------------
Index Scan using "<12659>btree_hypo_id" on hypo (cost=0.04..8.05 rows=1 width=13)
Index Cond: (id = 1)
(2 rows)
Now that the hypothetical index is being used, we can try hiding it to see the change:

.. code-block:: psql
:emphasize-lines: 10
SELECT hypopg_hide_index(12659);
hypopg_hide_index
-------------------
t
(1 row)
EXPLAIN SELECT * FROM hypo WHERE id = 1;
QUERY PLAN
-------------------------------------------------------------------------
Index Scan using hypo_id_idx on hypo (cost=0.29..8.30 rows=1 width=13)
Index Cond: (id = 1)
(2 rows)
SELECT * FROM hypopg_hidden_indexes;
indexrelid | index_name | schema_name | table_name | am_name | is_hypo
-------------+----------------------+-------------+------------+---------+---------
12659 | <12659>btree_hypo_id | public | hypo | btree | t
526604 | hypo_id_val_idx | public | hypo | btree | f
(2 rows)
.. note::

If a hypothetical index has been hidden, it will be automatically unhidden
when it is deleted using **hypopg_drop_index(oid)** or **hypopg_reset()**.

.. code-block:: psql
SELECT hypopg_drop_index(12659);
SELECT * FROM hypopg_hidden_indexes;
indexrelid | index_name | schema_name | table_name | am_name | is_hypo
-------------+----------------------+-------------+------------+---------+---------
526604 | hypo_id_val_idx | public | hypo | btree | f
(2 rows)
Loading

0 comments on commit 351f14a

Please sign in to comment.