mirror of
https://github.com/pgadmin-org/pgadmin4.git
synced 2024-12-22 15:13:42 -06:00
Added option to create unique index with nulls not distinct. #6368
This commit is contained in:
parent
557f33c4f9
commit
36949aef99
Binary file not shown.
Before Width: | Height: | Size: 42 KiB After Width: | Height: | Size: 71 KiB |
Binary file not shown.
Before Width: | Height: | Size: 44 KiB After Width: | Height: | Size: 77 KiB |
@ -54,6 +54,8 @@ Use the fields in the *Definition* tab to define the index:
|
||||
* Move the *Unique?* switch to the *Yes* position to check for duplicate values
|
||||
in the table when the index is created and when data is added. The default is
|
||||
*No*.
|
||||
* Move the *NULLs not distinct?* switch to the *Yes* position to treat null values as not distinct. The default is
|
||||
*No*. This option is available only on PostgreSQL 15 and above.
|
||||
* Move the *Clustered?* switch to the *Yes* position to instruct the server to
|
||||
cluster the table.
|
||||
* Move the *Concurrent build?* switch to the *Yes* position to build the index
|
||||
|
@ -51,6 +51,8 @@ Use the fields in the *Definition* tab to define the unique constraint:
|
||||
* If enabled, move the *Deferred?* switch to the *Yes* position to specify the
|
||||
timing of the constraint is deferred to the end of the statement. The default
|
||||
is *No*.
|
||||
* Move the *NULLs not distinct?* switch to the *Yes* position to treat null values as not distinct. The default is
|
||||
*No*. This option is available only on PostgreSQL 15 and above.
|
||||
|
||||
Click the *SQL* tab to continue.
|
||||
|
||||
|
@ -277,7 +277,7 @@ class IndexesView(PGChildNodeView, SchemaDiffObjectCompare):
|
||||
This function will return list of collation available
|
||||
via AJAX response
|
||||
"""
|
||||
res = [{'label': '', 'value': ''}]
|
||||
res = []
|
||||
try:
|
||||
SQL = render_template(
|
||||
"/".join([self.template_path, 'get_collations.sql'])
|
||||
@ -305,7 +305,7 @@ class IndexesView(PGChildNodeView, SchemaDiffObjectCompare):
|
||||
This function will return list of access methods available
|
||||
via AJAX response
|
||||
"""
|
||||
res = [{'label': '', 'value': ''}]
|
||||
res = []
|
||||
try:
|
||||
SQL = render_template("/".join([self.template_path, 'get_am.sql']))
|
||||
status, rset = self.conn.execute_2darray(SQL)
|
||||
@ -349,7 +349,7 @@ class IndexesView(PGChildNodeView, SchemaDiffObjectCompare):
|
||||
if not status:
|
||||
return internal_server_error(errormsg=res)
|
||||
|
||||
op_class_list = [{'label': '', 'value': ''}]
|
||||
op_class_list = []
|
||||
|
||||
for r in result['rows']:
|
||||
op_class_list.append({'label': r['opcname'],
|
||||
|
@ -359,10 +359,32 @@ export default class IndexSchema extends BaseUISchema {
|
||||
min: 10, max:100, group: gettext('Definition'),
|
||||
},{
|
||||
id: 'indisunique', label: gettext('Unique?'), cell: 'string',
|
||||
type: 'switch', disabled: () => inSchema(indexSchemaObj.node_info),
|
||||
type: 'switch', deps:['amname'], disabled: (state) => {
|
||||
return state.amname !== 'btree' || inSchema(indexSchemaObj.node_info);
|
||||
},
|
||||
readonly: function (state) {
|
||||
return !indexSchemaObj.isNew(state);
|
||||
},
|
||||
depChange: (state) => {
|
||||
if (state.amname !== 'btree') {
|
||||
return {indisunique:false};
|
||||
}
|
||||
},
|
||||
group: gettext('Definition'),
|
||||
},{
|
||||
id: 'indnullsnotdistinct', label: gettext('NULLs not distinct?'), cell: 'string',
|
||||
type: 'switch', deps:['indisunique', 'amname'], disabled: (state) => {
|
||||
return !state.indisunique || inSchema(indexSchemaObj.node_info);
|
||||
},
|
||||
readonly: function (state) {
|
||||
return !indexSchemaObj.isNew(state);
|
||||
},
|
||||
depChange: (state) => {
|
||||
if (!state.indisunique) {
|
||||
return {indnullsnotdistinct:false};
|
||||
}
|
||||
},
|
||||
min_version: 150000,
|
||||
group: gettext('Definition'),
|
||||
},{
|
||||
id: 'indisclustered', label: gettext('Clustered?'), cell: 'string',
|
||||
|
@ -0,0 +1,14 @@
|
||||
-- Index: Idx_$%{}[]()&*^!@"'`\/#
|
||||
|
||||
-- DROP INDEX IF EXISTS public."Idx_$%{}[]()&*^!@""'`\/#";
|
||||
|
||||
CREATE UNIQUE INDEX IF NOT EXISTS "Idx_$%{}[]()&*^!@""'`\/#"
|
||||
ON public.test_table_for_indexes USING btree
|
||||
(id ASC NULLS FIRST, name COLLATE pg_catalog."POSIX" text_pattern_ops ASC NULLS FIRST)
|
||||
NULLS NOT DISTINCT
|
||||
WITH (FILLFACTOR=10)
|
||||
TABLESPACE pg_default
|
||||
WHERE id < 100;
|
||||
|
||||
COMMENT ON INDEX public."Idx_$%{}[]()&*^!@""'`\/#"
|
||||
IS 'Test Comment';
|
@ -0,0 +1,10 @@
|
||||
CREATE UNIQUE INDEX "Idx_$%{}[]()&*^!@""'`\/#"
|
||||
ON public.test_table_for_indexes USING btree
|
||||
(id ASC NULLS FIRST, name COLLATE pg_catalog."POSIX" text_pattern_ops ASC NULLS FIRST)
|
||||
NULLS NOT DISTINCT
|
||||
WITH (FILLFACTOR=10)
|
||||
TABLESPACE pg_default
|
||||
WHERE id < 100;
|
||||
|
||||
COMMENT ON INDEX public."Idx_$%{}[]()&*^!@""'`\/#"
|
||||
IS 'Test Comment';
|
@ -0,0 +1,14 @@
|
||||
-- Index: Idx_$%{}[]()&*^!@"'`\/#
|
||||
|
||||
-- DROP INDEX IF EXISTS public."Idx_$%{}[]()&*^!@""'`\/#";
|
||||
|
||||
CREATE UNIQUE INDEX IF NOT EXISTS "Idx_$%{}[]()&*^!@""'`\/#"
|
||||
ON public.test_table_for_indexes USING btree
|
||||
(id ASC NULLS LAST, name COLLATE pg_catalog."POSIX" text_pattern_ops ASC NULLS LAST)
|
||||
NULLS NOT DISTINCT
|
||||
WITH (FILLFACTOR=10)
|
||||
TABLESPACE pg_default
|
||||
WHERE id < 100;
|
||||
|
||||
COMMENT ON INDEX public."Idx_$%{}[]()&*^!@""'`\/#"
|
||||
IS 'Test Comment';
|
@ -0,0 +1,10 @@
|
||||
CREATE UNIQUE INDEX "Idx_$%{}[]()&*^!@""'`\/#"
|
||||
ON public.test_table_for_indexes USING btree
|
||||
(id ASC NULLS LAST, name COLLATE pg_catalog."POSIX" text_pattern_ops ASC NULLS LAST)
|
||||
NULLS NOT DISTINCT
|
||||
WITH (FILLFACTOR=10)
|
||||
TABLESPACE pg_default
|
||||
WHERE id < 100;
|
||||
|
||||
COMMENT ON INDEX public."Idx_$%{}[]()&*^!@""'`\/#"
|
||||
IS 'Test Comment';
|
@ -0,0 +1,9 @@
|
||||
-- Index: Idx_$%{}[]()&*^!@"'`\/#
|
||||
|
||||
-- DROP INDEX IF EXISTS public."Idx_$%{}[]()&*^!@""'`\/#";
|
||||
|
||||
CREATE UNIQUE INDEX IF NOT EXISTS "Idx_$%{}[]()&*^!@""'`\/#"
|
||||
ON public.test_table_for_indexes USING btree
|
||||
(id DESC NULLS FIRST, name COLLATE pg_catalog."POSIX" text_pattern_ops DESC NULLS FIRST)
|
||||
NULLS NOT DISTINCT
|
||||
TABLESPACE pg_default;
|
@ -0,0 +1,5 @@
|
||||
CREATE UNIQUE INDEX "Idx_$%{}[]()&*^!@""'`\/#"
|
||||
ON public.test_table_for_indexes USING btree
|
||||
(id DESC NULLS FIRST, name COLLATE pg_catalog."POSIX" text_pattern_ops DESC NULLS FIRST)
|
||||
NULLS NOT DISTINCT
|
||||
TABLESPACE pg_default;
|
@ -0,0 +1,14 @@
|
||||
-- Index: Idx_$%{}[]()&*^!@"'`\/#
|
||||
|
||||
-- DROP INDEX IF EXISTS public."Idx_$%{}[]()&*^!@""'`\/#";
|
||||
|
||||
CREATE UNIQUE INDEX IF NOT EXISTS "Idx_$%{}[]()&*^!@""'`\/#"
|
||||
ON public.test_table_for_indexes USING btree
|
||||
(id DESC NULLS LAST, name COLLATE pg_catalog."POSIX" text_pattern_ops DESC NULLS LAST)
|
||||
NULLS NOT DISTINCT
|
||||
WITH (FILLFACTOR=10)
|
||||
TABLESPACE pg_default
|
||||
WHERE id < 100;
|
||||
|
||||
COMMENT ON INDEX public."Idx_$%{}[]()&*^!@""'`\/#"
|
||||
IS 'Test Comment';
|
@ -0,0 +1,10 @@
|
||||
CREATE UNIQUE INDEX "Idx_$%{}[]()&*^!@""'`\/#"
|
||||
ON public.test_table_for_indexes USING btree
|
||||
(id DESC NULLS LAST, name COLLATE pg_catalog."POSIX" text_pattern_ops DESC NULLS LAST)
|
||||
NULLS NOT DISTINCT
|
||||
WITH (FILLFACTOR=10)
|
||||
TABLESPACE pg_default
|
||||
WHERE id < 100;
|
||||
|
||||
COMMENT ON INDEX public."Idx_$%{}[]()&*^!@""'`\/#"
|
||||
IS 'Test Comment';
|
@ -0,0 +1,207 @@
|
||||
{
|
||||
"scenarios": [
|
||||
{
|
||||
"type": "create",
|
||||
"name": "Create Table for indexes",
|
||||
"endpoint": "NODE-table.obj",
|
||||
"sql_endpoint": "NODE-table.sql_id",
|
||||
"data": {
|
||||
"name": "test_table_for_indexes",
|
||||
"columns": [{
|
||||
"name": "id",
|
||||
"cltype": "bigint",
|
||||
"is_primary_key": true
|
||||
}, {
|
||||
"name": "name",
|
||||
"cltype": "text"
|
||||
}],
|
||||
"is_partitioned": false,
|
||||
"spcname": "pg_default",
|
||||
"schema": "public"
|
||||
},
|
||||
"store_object_id": true
|
||||
},
|
||||
{
|
||||
"type": "create",
|
||||
"name": "Create btree index with ASC and NULLS LAST -- 15 Plus",
|
||||
"endpoint": "NODE-index.obj",
|
||||
"sql_endpoint": "NODE-index.sql_id",
|
||||
"msql_endpoint": "NODE-index.msql",
|
||||
"data": {
|
||||
"name":"Idx_$%{}[]()&*^!@\"'`\\/#",
|
||||
"spcname":"pg_default",
|
||||
"amname":"btree",
|
||||
"columns":[{
|
||||
"colname":"id",
|
||||
"collspcname":"",
|
||||
"op_class":"",
|
||||
"sort_order":false,
|
||||
"nulls":false,
|
||||
"is_sort_nulls_applicable":true
|
||||
}, {
|
||||
"colname":"name",
|
||||
"collspcname":"pg_catalog.\"POSIX\"",
|
||||
"op_class":"text_pattern_ops",
|
||||
"sort_order":false,
|
||||
"nulls":false,
|
||||
"is_sort_nulls_applicable":true
|
||||
}],
|
||||
"description":"Test Comment",
|
||||
"fillfactor":"10",
|
||||
"indisunique":true,
|
||||
"indnullsnotdistinct":true,
|
||||
"indisclustered":false,
|
||||
"isconcurrent":false,
|
||||
"indconstraint":"id < 100"
|
||||
},
|
||||
"expected_sql_file": "create_btree_asc_null_last.sql",
|
||||
"expected_msql_file": "create_btree_asc_null_last_msql.sql"
|
||||
},
|
||||
{
|
||||
"type": "delete",
|
||||
"name": "Drop index -- 15 Plus",
|
||||
"endpoint": "NODE-index.delete_id",
|
||||
"data": {
|
||||
"name": "Idx_$%{}[]()&*^!@\"'`\\/#"
|
||||
}
|
||||
},
|
||||
{
|
||||
"type": "create",
|
||||
"name": "Create btree index with ASC and NULLS FIRST -- 15 Plus",
|
||||
"endpoint": "NODE-index.obj",
|
||||
"sql_endpoint": "NODE-index.sql_id",
|
||||
"msql_endpoint": "NODE-index.msql",
|
||||
"data": {
|
||||
"name":"Idx_$%{}[]()&*^!@\"'`\\/#",
|
||||
"spcname":"pg_default",
|
||||
"amname":"btree",
|
||||
"columns":[{
|
||||
"colname":"id",
|
||||
"collspcname":"",
|
||||
"op_class":"",
|
||||
"sort_order":false,
|
||||
"nulls":true,
|
||||
"is_sort_nulls_applicable":true
|
||||
}, {
|
||||
"colname":"name",
|
||||
"collspcname":"pg_catalog.\"POSIX\"",
|
||||
"op_class":"text_pattern_ops",
|
||||
"sort_order":false,
|
||||
"nulls":true,
|
||||
"is_sort_nulls_applicable":true
|
||||
}],
|
||||
"description":"Test Comment",
|
||||
"fillfactor":"10",
|
||||
"indisunique":true,
|
||||
"indnullsnotdistinct":true,
|
||||
"indisclustered":false,
|
||||
"isconcurrent":false,
|
||||
"indconstraint":"id < 100"
|
||||
},
|
||||
"expected_sql_file": "create_btree_asc_null_first.sql",
|
||||
"expected_msql_file": "create_btree_asc_null_first_msql.sql"
|
||||
},
|
||||
{
|
||||
"type": "delete",
|
||||
"name": "Drop index -- 15 Plus",
|
||||
"endpoint": "NODE-index.delete_id",
|
||||
"data": {
|
||||
"name": "Idx_$%{}[]()&*^!@\"'`\\/#"
|
||||
}
|
||||
},
|
||||
{
|
||||
"type": "create",
|
||||
"name": "Create btree index with DESC and NULLS LAST -- 15 Plus",
|
||||
"endpoint": "NODE-index.obj",
|
||||
"sql_endpoint": "NODE-index.sql_id",
|
||||
"msql_endpoint": "NODE-index.msql",
|
||||
"data": {
|
||||
"name":"Idx_$%{}[]()&*^!@\"'`\\/#",
|
||||
"spcname":"pg_default",
|
||||
"amname":"btree",
|
||||
"columns":[{
|
||||
"colname":"id",
|
||||
"collspcname":"",
|
||||
"op_class":"",
|
||||
"sort_order":true,
|
||||
"nulls":false,
|
||||
"is_sort_nulls_applicable":true
|
||||
}, {
|
||||
"colname":"name",
|
||||
"collspcname":"pg_catalog.\"POSIX\"",
|
||||
"op_class":"text_pattern_ops",
|
||||
"sort_order":true,
|
||||
"nulls":false,
|
||||
"is_sort_nulls_applicable":true
|
||||
}],
|
||||
"description":"Test Comment",
|
||||
"fillfactor":"10",
|
||||
"indisunique":true,
|
||||
"indnullsnotdistinct":true,
|
||||
"indisclustered":false,
|
||||
"isconcurrent":false,
|
||||
"indconstraint":"id < 100"
|
||||
},
|
||||
"expected_sql_file": "create_btree_desc_null_last.sql",
|
||||
"expected_msql_file": "create_btree_desc_null_last_msql.sql"
|
||||
},
|
||||
{
|
||||
"type": "delete",
|
||||
"name": "Drop index -- 15 Plus",
|
||||
"endpoint": "NODE-index.delete_id",
|
||||
"data": {
|
||||
"name": "Idx_$%{}[]()&*^!@\"'`\\/#"
|
||||
}
|
||||
},
|
||||
{
|
||||
"type": "create",
|
||||
"name": "Create btree index with DESC and NULLS FIRST -- 15 Plus",
|
||||
"endpoint": "NODE-index.obj",
|
||||
"sql_endpoint": "NODE-index.sql_id",
|
||||
"msql_endpoint": "NODE-index.msql",
|
||||
"data": {
|
||||
"name":"Idx_$%{}[]()&*^!@\"'`\\/#",
|
||||
"spcname":"pg_default",
|
||||
"amname":"btree",
|
||||
"columns":[{
|
||||
"colname":"id",
|
||||
"collspcname":"",
|
||||
"op_class":"",
|
||||
"sort_order":true,
|
||||
"nulls":true,
|
||||
"is_sort_nulls_applicable":true
|
||||
}, {
|
||||
"colname":"name",
|
||||
"collspcname":"pg_catalog.\"POSIX\"",
|
||||
"op_class":"text_pattern_ops",
|
||||
"sort_order":true,
|
||||
"nulls":true,
|
||||
"is_sort_nulls_applicable":true
|
||||
}],
|
||||
"indisunique":true,
|
||||
"indnullsnotdistinct":true,
|
||||
"indisclustered":false,
|
||||
"isconcurrent":false
|
||||
},
|
||||
"expected_sql_file": "create_btree_desc_null_first.sql",
|
||||
"expected_msql_file": "create_btree_desc_null_first_msql.sql"
|
||||
},
|
||||
{
|
||||
"type": "delete",
|
||||
"name": "Drop index -- 15 Plus",
|
||||
"endpoint": "NODE-index.delete_id",
|
||||
"data": {
|
||||
"name": "Idx1_$%{}[]()&*^!@\"'`\\/#"
|
||||
}
|
||||
},
|
||||
{
|
||||
"type": "delete",
|
||||
"name": "Drop Table",
|
||||
"endpoint": "NODE-table.delete_id",
|
||||
"data": {
|
||||
"name": "test_table_for_indexes"
|
||||
}
|
||||
}
|
||||
]
|
||||
}
|
||||
|
@ -192,6 +192,67 @@
|
||||
"error_msg": "table_id",
|
||||
"test_result_data": {}
|
||||
}
|
||||
},
|
||||
{
|
||||
"name": "Create index: Unique index",
|
||||
"is_positive_test": true,
|
||||
"inventory_data": {},
|
||||
"test_data": {
|
||||
"name": "test_index_add",
|
||||
"spcname": "pg_default",
|
||||
"amname": "btree",
|
||||
"indisunique":true,
|
||||
"indnullsnotdistinct":true,
|
||||
"columns": [
|
||||
{
|
||||
"colname": "id",
|
||||
"sort_order": false,
|
||||
"nulls": false
|
||||
}
|
||||
],
|
||||
"include": [
|
||||
"name"
|
||||
]
|
||||
},
|
||||
"mocking_required": false,
|
||||
"mock_data": {},
|
||||
"expected_data": {
|
||||
"status_code": 200,
|
||||
"error_msg": null,
|
||||
"test_result_data": {}
|
||||
}
|
||||
},
|
||||
{
|
||||
"name": "Create index: Unique index With nulls not distinct.",
|
||||
"is_positive_test": true,
|
||||
"inventory_data": {
|
||||
"server_min_version": 150000,
|
||||
"skip_msg": "Nulls not distinct is not supported by PPAS/PG 15.0 and below."
|
||||
},
|
||||
"test_data": {
|
||||
"name": "test_index_add",
|
||||
"spcname": "pg_default",
|
||||
"amname": "btree",
|
||||
"indisunique":true,
|
||||
"indnullsnotdistinct":true,
|
||||
"columns": [
|
||||
{
|
||||
"colname": "id",
|
||||
"sort_order": false,
|
||||
"nulls": false
|
||||
}
|
||||
],
|
||||
"include": [
|
||||
"name"
|
||||
]
|
||||
},
|
||||
"mocking_required": false,
|
||||
"mock_data": {},
|
||||
"expected_data": {
|
||||
"status_code": 200,
|
||||
"error_msg": null,
|
||||
"test_result_data": {}
|
||||
}
|
||||
}
|
||||
],
|
||||
"index_get": [
|
||||
|
@ -21,6 +21,7 @@ from pgadmin.utils.route import BaseTestGenerator
|
||||
from regression import parent_node_dict
|
||||
from regression.python_test_utils import test_utils as utils
|
||||
from . import utils as indexes_utils
|
||||
from pgadmin.utils import server_utils
|
||||
|
||||
|
||||
class IndexesAddTestCase(BaseTestGenerator):
|
||||
@ -31,9 +32,20 @@ class IndexesAddTestCase(BaseTestGenerator):
|
||||
|
||||
def setUp(self):
|
||||
super().setUp()
|
||||
self.db_name = parent_node_dict["database"][-1]["db_name"]
|
||||
|
||||
schema_info = parent_node_dict["schema"][-1]
|
||||
self.server_id = schema_info["server_id"]
|
||||
|
||||
if "server_min_version" in self.inventory_data:
|
||||
server_con = server_utils.connect_server(self, self.server_id)
|
||||
if not server_con["info"] == "Server connected.":
|
||||
raise Exception("Could not connect to server to add "
|
||||
"partitioned table.")
|
||||
if server_con["data"]["version"] < \
|
||||
self.inventory_data["server_min_version"]:
|
||||
self.skipTest(self.inventory_data["skip_msg"])
|
||||
|
||||
self.db_name = parent_node_dict["database"][-1]["db_name"]
|
||||
self.db_id = schema_info["db_id"]
|
||||
db_con = database_utils.connect_database(self, utils.SERVER_GROUP,
|
||||
self.server_id, self.db_id)
|
||||
|
@ -0,0 +1,32 @@
|
||||
CREATE{% if data.indisunique %} UNIQUE{% endif %} INDEX{% if add_not_exists_clause %} IF NOT EXISTS{% endif %}{% if data.isconcurrent %} CONCURRENTLY{% endif %}{% if data.name %} {{conn|qtIdent(data.name)}}{% endif %}
|
||||
|
||||
ON {{conn|qtIdent(data.schema, data.table)}} {% if data.amname %}USING {{conn|qtIdent(data.amname)}}{% endif %}
|
||||
|
||||
{% if mode == 'create' %}
|
||||
({% for c in data.columns %}{% if loop.index != 1 %}, {% endif %}{{conn|qtIdent(c.colname)}}{% if c.collspcname %} COLLATE {{c.collspcname}}{% endif %}{% if c.op_class %}
|
||||
{{c.op_class}}{% endif %}{% if data.amname is defined %}{% if c.sort_order is defined and c.is_sort_nulls_applicable %}{% if c.sort_order %} DESC{% else %} ASC{% endif %}{% endif %}{% if c.nulls is defined and c.is_sort_nulls_applicable %} NULLS {% if c.nulls %}
|
||||
FIRST{% else %}LAST{% endif %}{% endif %}{% endif %}{% endfor %})
|
||||
{% if data.include|length > 0 %}
|
||||
INCLUDE({% for col in data.include %}{% if loop.index != 1 %}, {% endif %}{{conn|qtIdent(col)}}{% endfor %})
|
||||
{% endif %}
|
||||
{% if data.indnullsnotdistinct %}
|
||||
NULLS NOT DISTINCT
|
||||
{% endif %}
|
||||
{% else %}
|
||||
{## We will get indented data from postgres for column ##}
|
||||
({% for c in data.columns %}{% if loop.index != 1 %}, {% endif %}{{c.colname}}{% if c.collspcname %} COLLATE {{c.collspcname}}{% endif %}{% if c.op_class %}
|
||||
{{c.op_class}}{% endif %}{% if c.sort_order is defined %}{% if c.sort_order %} DESC{% else %} ASC{% endif %}{% endif %}{% if c.nulls is defined %} NULLS {% if c.nulls %}
|
||||
FIRST{% else %}LAST{% endif %}{% endif %}{% endfor %})
|
||||
{% if data.include|length > 0 %}
|
||||
INCLUDE({% for col in data.include %}{% if loop.index != 1 %}, {% endif %}{{conn|qtIdent(col)}}{% endfor %})
|
||||
{% endif %}
|
||||
{% if data.indnullsnotdistinct %}
|
||||
NULLS NOT DISTINCT
|
||||
{% endif %}
|
||||
{% endif %}
|
||||
{% if data.fillfactor %}
|
||||
WITH (FILLFACTOR={{data.fillfactor}})
|
||||
{% endif %}{% if data.spcname %}
|
||||
TABLESPACE {{conn|qtIdent(data.spcname)}}{% endif %}{% if data.indconstraint %}
|
||||
|
||||
WHERE {{data.indconstraint}}{% endif %};
|
@ -0,0 +1,28 @@
|
||||
SELECT DISTINCT ON(cls.relname) cls.oid, cls.relname as name, indrelid, indkey, indisclustered,
|
||||
indisvalid, indisunique, indisprimary, n.nspname,indnatts,cls.reltablespace AS spcoid, indnullsnotdistinct,
|
||||
CASE WHEN (length(spcname::text) > 0 OR cls.relkind = 'I') THEN spcname ELSE
|
||||
(SELECT sp.spcname FROM pg_catalog.pg_database dtb
|
||||
JOIN pg_catalog.pg_tablespace sp ON dtb.dattablespace=sp.oid
|
||||
WHERE dtb.oid = {{ did }}::oid)
|
||||
END as spcname,
|
||||
tab.relname as tabname, indclass, con.oid AS conoid,
|
||||
CASE WHEN contype IN ('p', 'u', 'x') THEN desp.description
|
||||
ELSE des.description END AS description,
|
||||
pg_catalog.pg_get_expr(indpred, indrelid, true) as indconstraint, contype, condeferrable, condeferred, amname,
|
||||
(SELECT (CASE WHEN count(i.inhrelid) > 0 THEN true ELSE false END) FROM pg_inherits i WHERE i.inhrelid = cls.oid) as is_inherited,
|
||||
substring(pg_catalog.array_to_string(cls.reloptions, ',') from 'fillfactor=([0-9]*)') AS fillfactor
|
||||
{% if datlastsysoid %}, (CASE WHEN cls.oid <= {{ datlastsysoid}}::oid THEN true ElSE false END) AS is_sys_idx {% endif %}
|
||||
FROM pg_catalog.pg_index idx
|
||||
JOIN pg_catalog.pg_class cls ON cls.oid=indexrelid
|
||||
JOIN pg_catalog.pg_class tab ON tab.oid=indrelid
|
||||
LEFT OUTER JOIN pg_catalog.pg_tablespace ta on ta.oid=cls.reltablespace
|
||||
JOIN pg_catalog.pg_namespace n ON n.oid=tab.relnamespace
|
||||
JOIN pg_catalog.pg_am am ON am.oid=cls.relam
|
||||
LEFT JOIN pg_catalog.pg_depend dep ON (dep.classid = cls.tableoid AND dep.objid = cls.oid AND dep.refobjsubid = '0' AND dep.refclassid=(SELECT oid FROM pg_catalog.pg_class WHERE relname='pg_constraint') AND dep.deptype='i')
|
||||
LEFT OUTER JOIN pg_catalog.pg_constraint con ON (con.tableoid = dep.refclassid AND con.oid = dep.refobjid)
|
||||
LEFT OUTER JOIN pg_catalog.pg_description des ON (des.objoid=cls.oid AND des.classoid='pg_class'::regclass)
|
||||
LEFT OUTER JOIN pg_catalog.pg_description desp ON (desp.objoid=con.oid AND desp.objsubid = 0 AND desp.classoid='pg_constraint'::regclass)
|
||||
WHERE indrelid = {{tid}}::OID
|
||||
AND conname is NULL
|
||||
{% if idx %}AND cls.oid = {{idx}}::OID {% endif %}
|
||||
ORDER BY cls.relname
|
Loading…
Reference in New Issue
Block a user