File: hypo_hide_index.sql

package info (click to toggle)
hypopg 1.4.2-2
  • links: PTS, VCS
  • area: main
  • in suites: forky, sid
  • size: 464 kB
  • sloc: ansic: 2,338; sql: 357; makefile: 66; python: 51; sh: 2
file content (100 lines) | stat: -rw-r--r-- 3,554 bytes parent folder | download | duplicates (3)
1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
18
19
20
21
22
23
24
25
26
27
28
29
30
31
32
33
34
35
36
37
38
39
40
41
42
43
44
45
46
47
48
49
50
51
52
53
54
55
56
57
58
59
60
61
62
63
64
65
66
67
68
69
70
71
72
73
74
75
76
77
78
79
80
81
82
83
84
85
86
87
88
89
90
91
92
93
94
95
96
97
98
99
100
-- Hypothetically hiding existing indexes tests

-- Remove all the hypothetical indexes if any
SELECT hypopg_reset();

-- The EXPLAIN initial state
SELECT COUNT(*) FROM do_explain('SELECT * FROM hypo WHERE id = 1') e
WHERE e ~ 'hypo_id_idx';

-- Create real index in hypo and use this index
CREATE INDEX hypo_id_idx ON hypo(id);
SELECT COUNT(*) FROM do_explain('SELECT * FROM hypo WHERE id = 1') e
WHERE e ~ 'hypo_id_idx';

-- Should be zero
SELECT COUNT(*) FROM hypopg_hidden_indexes();

-- The hypo_id_idx index should not be used
SELECT hypopg_hide_index('hypo_id_idx'::regclass);
SELECT COUNT(*) FROM do_explain('SELECT * FROM hypo WHERE id = 1') e
WHERE e ~ 'hypo_id_idx';

-- Should be only one record
SELECT COUNT(*) FROM hypopg_hidden_indexes();
SELECT table_name,index_name FROM hypopg_hidden_indexes;

-- Create the real index again and
-- EXPLAIN should use this index instead of the previous one
CREATE index hypo_id_val_idx ON hypo(id, val);
SELECT COUNT(*) FROM do_explain('SELECT * FROM hypo WHERE id = 1') e
WHERE e ~ 'hypo_id_val_idx';

-- Shouldn't use any index
SELECT hypopg_hide_index('hypo_id_val_idx'::regclass);
SELECT COUNT(*) FROM do_explain('SELECT * FROM hypo WHERE id = 1') e
WHERE e ~ 'hypo_id_val_idx';

-- Should be two records
SELECT table_name,index_name FROM hypopg_hidden_indexes;

-- Try to add one repeatedly or add another wrong index oid
SELECT hypopg_hide_index('hypo_id_idx'::regclass);
SELECT hypopg_hide_index('hypo'::regclass);
SELECT hypopg_hide_index(0);

-- Also of course can be used to hide hypothetical indexes
SELECT COUNT(*) FROM hypopg_create_index('create index on hypo(id,val);');
SELECT COUNT(*) FROM do_explain('SELECT * FROM hypo WHERE id = 1') e
WHERE e ~ 'Index.*<\d+>btree_hypo.*';
SELECT hypopg_hide_index((SELECT indexrelid FROM hypopg_list_indexes LIMIT 1));
SELECT COUNT(*) FROM do_explain('SELECT * FROM hypo WHERE id = 1') e
WHERE e ~ 'Index.*<\d+>btree_hypo.*';

-- Should be only three records
SELECT COUNT(*) FROM hypopg_hidden_indexes;

-- Hypothetical indexes should be unhidden when deleting
SELECT hypopg_drop_index((SELECT indexrelid FROM hypopg_list_indexes LIMIT 1));

-- Should become two records
SELECT COUNT(*) FROM hypopg_hidden_indexes;

-- Hypopg_reset can also unhidden the hidden indexes
-- due to the deletion of hypothetical indexes.
SELECT COUNT(*) FROM hypopg_create_index('create index on hypo(id,val);');
SELECT COUNT(*) FROM do_explain('SELECT * FROM hypo WHERE id = 1') e
WHERE e ~ 'Index.*<\d+>btree_hypo.*';
SELECT hypopg_hide_index((SELECT indexrelid FROM hypopg_list_indexes LIMIT 1));

-- Changed from three records to two records.
SELECT COUNT(*) FROM hypopg_hidden_indexes;
SELECT hypopg_reset();
SELECT COUNT(*) FROM hypopg_hidden_indexes;

-- Unhide an index
SELECT hypopg_unhide_index('hypo_id_idx'::regclass);
SELECT COUNT(*) FROM do_explain('SELECT * FROM hypo WHERE id = 1') e
WHERE e ~ 'hypo_id_idx';

-- Should become one record
SELECT table_name,index_name FROM hypopg_hidden_indexes;

-- Try to delete one repeatedly or delete another wrong index oid
SELECT hypopg_unhide_index('hypo_id_idx'::regclass);
SELECT hypopg_unhide_index('hypo'::regclass);
SELECT hypopg_unhide_index(0);

-- Should still have one record
SELECT table_name,index_name FROM hypopg_hidden_indexes;

-- Unhide all indexes
SELECT hypopg_unhide_all_indexes();

-- Should change back to the original zero
SELECT COUNT(*) FROM hypopg_hidden_indexes();

-- Clean real indexes and hypothetical indexes
DROP INDEX hypo_id_idx;
DROP INDEX hypo_id_val_idx;
SELECT hypopg_reset();