学习目标
掌握openGauss DBMS索引的管理:创建索引、删除索引、查询索引的信息、修改索引的信息。介绍
索引可以提高数据的访问速度,但同时也增加了插入、更新和删除操作的处理时间。所以是否要为表增加索引,索引建立在哪些字段上,是创建索引前必须要考虑的问题。需要分析应用程序的业务处理、数据使用、经常被用作查询的条件或者被要求排序的字段来确定是否建立索引。
索引建立在数据库表中的某些列上。因此,在创建索引时,应该仔细考虑在哪些列上创建索引
在经常需要搜索查询的列上创建索引,可以加快搜索的速度。
在作为主键的列上创建索引,强制该列的唯一性和组织表中数据的排列结构。
在经常需要根据范围进行搜索的列上创建索引,因为索引已经排序,其指定的范围是连续的。
在经常需要排序的列上创建索引,因为索引已经排序,这样查询可以利用索引的排序,加快排序查询时间。
在经常使用WHERE子句的列上创建索引,加快条件的判断速度。
为经常出现在关键字ORDER BY、GROUP BY、DISTINCT后面的字段建立索引。
说明:
索引可以分为以下几类索引:
唯一索引:可用于约束索引属性值的唯一性,或者属性组合值的唯一性。如果一个表声明了唯一约束或者主键,则openGauss自动在组成主键或唯一约束的字段上创建唯一索引(可能是多字段索引),以实现这些约束。目前,openGauss只有B-Tree可以创建唯一索引。
多字段索引:一个索引可以定义在表中的多个属性上。目前,openGauss中的B-Tree支持多字段索引,且最多可在32个字段上创建索引(全局分区索引最多支持31个字段)。
部分索引:建立在一个表的子集上的索引,这种索引方式只包含满足条件表达式的元组。
表达式索引:索引建立在一个函数或者从表中一个或多个属性计算出来的表达式上。表达式索引只有在查询时使用与创建时相同的表达式才会起作用。
课程学习
索引是一个指向表中数据的指针。一个数据库中的索引与一本书的索引目录是非常相似的。索引可以用来提高数据库查询性能,但是不恰当的使用将导致数据库性能下降。
1.创建索引
--为表test的testnum列创建一个索引
su - omm
gsql -r
drop table if exists test;
create table test(id serial primary key,testnum serial);
create index idx_test_testnum on test(testnum);
--查看索引
\di
[omm@opengauss ~]$ gsql -r
gsql ((openGauss 3.1.0 build 4e931f9a) compiled at 2022-09-29 14:19:24 commit 0 last mr )
Non-SSL connection (SSL connection is recommended when requiring high-security)
Type "help" for help.
omm=# drop table if exists test;
NOTICE: table "test" does not exist, skipping
DROP TABLE
omm=# create table test(id serial primary key,testnum serial);
NOTICE: CREATE TABLE will create implicit sequence "test_id_seq" for serial column "test.id"
NOTICE: CREATE TABLE will create implicit sequence "test_testnum_seq" for serial column "test.testnum"
NOTICE: CREATE TABLE / PRIMARY KEY will create implicit index "test_pkey" for table "test"
CREATE TABLE
omm=#
omm=# create index idx_test_testnum on test(testnum);
CREATE INDEX
omm=# \di
List of relations
Schema | Name | Type | Owner | Table | Storage
--------+------------------+-------+-------+-------+---------
public | idx_test_testnum | index | omm | test |
public | test_pkey | index | omm | test |
(2 rows)
omm=#2.通过hint使用索引
--测试准备,创建表customer,并插入数据
CREATE TABLE customer
(
ca_address_sk integer NOT NULL ,
ca_address_id character(16),
ca_street_number character(10) ,
ca_street_name character varying(60) ,
ca_street_type character(15) ,
ca_suite_number character(10) ,
ca_city character varying(60) ,
ca_county character varying(30) ,
ca_state character(2) ,
ca_zip character(10) ,
ca_country character varying(20) ,
ca_gmt_offset numeric(5,2) ,
ca_location_type character(20)
);
insert into customer values
(1, 'AAAAAAAABAAAAAAA', '18', 'Jackson', 'Parkway', 'Suite 280', 'Fairfield', 'Maricopa County', 'AZ', '86192' ,'United States', -7.00, 'condo'),
(2, 'AAAAAAAACAAAAAAA', '362', 'Washington 6th', 'RD', 'Suite 80', 'Fairview', 'Taos County', 'NM', '85709', 'United States', -7.00, 'condo'),
(3, 'AAAAAAAADAAAAAAA', '585', 'Dogwood Washington', 'Circle', 'Suite Q', 'Pleasant Valley', 'York County', 'PA', '12477', 'United States', -5.00, 'single family');
--创建索引
create index customer_idx on customer(ca_address_sk);
--通过hint强制使用索引,查看执行计划
EXPLAIN SELECT /*+ indexscan(customer customer_idx ) */
* FROM customer WHERE ca_address_sk<100;
omm=# CREATE TABLE customer
omm-# (
omm(# ca_address_sk integer NOT NULL ,
omm(# ca_address_id character(16),
omm(# ca_street_number character(10) ,
omm(# ca_street_name character varying(60) ,
omm(# ca_street_type character(15) ,
omm(# ca_suite_number character(10) ,
omm(# ca_city character varying(60) ,
omm(# ca_county character varying(30) ,
omm(# ca_state character(2) ,
omm(# ca_zip character(10) ,
omm(# ca_country character varying(20) ,
omm(# ca_gmt_offset numeric(5,2) ,
omm(# ca_location_type character(20)
omm(# );
CREATE TABLE
omm=# insert into customer values
omm-# (1, 'AAAAAAAABAAAAAAA', '18', 'Jackson', 'Parkway', 'Suite 280', 'Fairfield', 'Maricopa County', 'AZ', '86192' ,'United States', -7.00, 'condo'),
omm-# (2, 'AAAAAAAACAAAAAAA', '362', 'Washington 6th', 'RD', 'Suite 80', 'Fairview', 'Taos County', 'NM', '85709', 'United States', -7.00, 'condo'),
omm-# (3, 'AAAAAAAADAAAAAAA', '585', 'Dogwood Washington', 'Circle', 'Suite Q', 'Pleasant Valley', 'York County', 'PA', '12477', 'United States', -5.00, 'single family');
INSERT 0 3
omm=# create index customer_idx on customer(ca_address_sk);
CREATE INDEX
omm=# EXPLAIN SELECT /*+ indexscan(customer customer_idx ) */
omm-# * FROM customer WHERE ca_address_sk<100;
QUERY PLAN
-------------------------------------------------------------------------------
[Bypass]
Index Scan using customer_idx on customer (cost=0.00..8.27 rows=1 width=788)
Index Cond: (ca_address_sk < 100)
(3 rows)
omm=#
3.rename重命名索引
ALTER INDEX idx_test_testnum RENAME TO idx_test_testnum_new;
omm=# ALTER INDEX idx_test_testnum RENAME TO idx_test_testnum_new;
ALTER INDEX
omm=#4.重建索引
--重建一个单独索引
ALTER INDEX idx_test_testnum_new REBUILD;
REINDEX INDEX idx_test_testnum_new;
--重建所有索引
reindex table test;
omm=# ALTER INDEX idx_test_testnum_new REBUILD;
REINDEX
omm=# REINDEX INDEX idx_test_testnum_new;
REINDEX
omm=# reindex table test;
REINDEX
omm=#5.移动索引到其他表空间
--创建表空间myindex_ts:
CREATE TABLESPACE myindex_ts RELATIVE LOCATION 'tablespace/myindex_ts1';
--将索引idx_test_testnum_new移动到表空间myindex_ts:
ALTER INDEX idx_test_testnum_new SET TABLESPACE myindex_ts;
--查看索引所在的表空间
select * from pg_indexes where tablename = 'test';
--或
select * from pg_indexes where indexname = 'idx_test_testnum_new';
omm=# CREATE TABLESPACE myindex_ts RELATIVE LOCATION 'tablespace/myindex_ts1';
CREATE TABLESPACE
omm=# ALTER INDEX idx_test_testnum_new SET TABLESPACE myindex_ts;
ALTER INDEX
omm=# select * from pg_indexes where tablename = 'test';
schemaname | tablename | indexname | tablespace |
indexdef
------------+-----------+----------------------+------------+--------------------------------
-------------------------------------------------------
public | test | test_pkey | | CREATE UNIQUE INDEX test_pkey O
N test USING btree (id) TABLESPACE pg_default
public | test | idx_test_testnum_new | myindex_ts | CREATE INDEX idx_test_testnum_n
ew ON test USING btree (testnum) TABLESPACE myindex_ts
(2 rows)
omm=# select * from pg_indexes where indexname = 'idx_test_testnum_new';
schemaname | tablename | indexname | tablespace |
indexdef
------------+-----------+----------------------+------------+--------------------------------
-------------------------------------------------------
public | test | idx_test_testnum_new | myindex_ts | CREATE INDEX idx_test_testnum_n
ew ON test USING btree (testnum) TABLESPACE myindex_ts
(1 row)
omm=# 6.删除索引
--执行下面的命令,删除表test上的索引idx_test_testnum_new:
drop index idx_test_testnum_new;
omm=# drop index idx_test_testnum_new;
DROP INDEX
omm=#
课程作业
1.创建表,在表中创建索引create table txiaocx(id int,name varchar(20));
create index idx_txiaocx_id on txiaocx(id);
insert into txiaocx values(1,'user1');
insert into txiaocx values(2,'user2');
insert into txiaocx values(3,'user3');
insert into txiaocx values(4,'user4');
insert into txiaocx values(5,'user5');
insert into txiaocx values(6,'user6');
insert into txiaocx values(7,'xiaocx1');
insert into txiaocx values(8,'xiaocx2');
insert into txiaocx values(9,'xiaocx3');
insert into txiaocx values(10,'xiaocx4');
select * from txiaocx;
\di
omm=# create table txiaocx(id int,name varchar(20));
CREATE TABLE
omm=# create index idx_txiaocx_id on txiaocx(id);
to txiaocx values(5,'user5');
insert into txiaocx values(6,'user6');
insert into txiaocx values(7,'xiaocx1');
insert into txiaocx values(8,'xiaocx2');
insert into txiaocx values(9,'xiaocx3');
insert into txiaocx values(10,'xiaocx4');
select * from txiaocx;CREATE INDEX
omm=# insert into txiaocx values(1,'user1');
INSERT 0 1
omm=# insert into txiaocx values(2,'user2');
INSERT 0 1
omm=# insert into txiaocx values(3,'user3');
INSERT 0 1
omm=# insert into txiaocx values(4,'user4');
INSERT 0 1
omm=# insert into txiaocx values(5,'user5');
INSERT 0 1
omm=# insert into txiaocx values(6,'user6');
INSERT 0 1
omm=# insert into txiaocx values(7,'xiaocx1');
INSERT 0 1
omm=# insert into txiaocx values(8,'xiaocx2');
INSERT 0 1
omm=# insert into txiaocx values(9,'xiaocx3');
INSERT 0 1
omm=# insert into txiaocx values(10,'xiaocx4');
INSERT 0 1
omm=# select * from txiaocx;
id | name
----+---------
1 | user1
2 | user2
3 | user3
4 | user4
5 | user5
6 | user6
7 | xiaocx1
8 | xiaocx2
9 | xiaocx3
10 | xiaocx4
(10 rows)
omm=# \di
List of relations
Schema | Name | Type | Owner | Table | Storage
--------+----------------+-------+-------+----------+---------
public | customer_idx | index | omm | customer |
public | idx_txiaocx_id | index | omm | txiaocx |
public | test_pkey | index | omm | test |
(3 rows)
omm=#
2.通过hint使用索引
EXPLAIN SELECT /*+ indexscan(txiaocx idx_txiaocx_id ) */ * FROM txiaocx WHERE id<6;
omm=# EXPLAIN SELECT /*+ indexscan(txiaocx idx_txiaocx_id ) */ * FROM txiaocx WHERE id<6;
QUERY PLAN
----------------------------------------------------------------------------------
[Bypass]
Index Scan using idx_txiaocx_id on txiaocx (cost=0.00..49.43 rows=296 width=62)
Index Cond: (id < 6)
(3 rows)
omm=#3.rename索引
ALTER INDEX idx_txiaocx_id RENAME TO idx_txiaocx_id_new;
\di
omm=# ALTER INDEX idx_txiaocx_id RENAME TO idx_txiaocx_id_new;
ALTER INDEX
omm=#
omm=#
omm=# \di
List of relations
Schema | Name | Type | Owner | Table | Storage
--------+--------------------+-------+-------+----------+---------
public | customer_idx | index | omm | customer |
public | idx_txiaocx_id_new | index | omm | txiaocx |
public | test_pkey | index | omm | test |
(3 rows)
omm=#4.重建索引
reindex table txiaocx;
omm=# reindex table txiaocx;
REINDEX
omm=#omm=# \di
List of relations
Schema | Name | Type | Owner | Table | Storage
--------+----------------+-------+-------+----------+---------
public | customer_idx | index | omm | customer |
public | idx_txiaocx_id | index | omm | txiaocx |
public | test_pkey | index | omm | test |
(3 rows)
omm=#
5.移动索引到其他表空间
CREATE TABLESPACE xiaocx_ts RELATIVE LOCATION 'tablespace/xiaocx_ts';
ALTER INDEX idx_txiaocx_id_new SET TABLESPACE xiaocx_ts;
select * from pg_indexes where tablename = 'txiaocx';
--or
select * from pg_indexes where indexname = 'idx_txiaocx_id_new';
omm=# CREATE TABLESPACE xiaocx_ts RELATIVE LOCATION 'tablespace/xiaocx_ts';
CREATE TABLESPACE
omm=# ALTER INDEX idx_txiaocx_id_new SET TABLESPACE xiaocx_ts;
ALTER INDEX
omm=# select * from pg_indexes where tablename = 'txiaocx';
schemaname | tablename | indexname | tablespace |
indexdef
------------+-----------+--------------------+------------+----------------------------------------------------------------------------------
public | txiaocx | idx_txiaocx_id_new | xiaocx_ts | CREATE INDEX idx_txiaocx_id_new ON txiaocx USING btree (id) TABLESPACE xiaocx_ts
(1 row)
omm=# --or
omm=# select * from pg_indexes where indexname = 'idx_txiaocx_id_new';
schemaname | tablename | indexname | tablespace |
indexdef
------------+-----------+--------------------+------------+----------------------------------------------------------------------------------
public | txiaocx | idx_txiaocx_id_new | xiaocx_ts | CREATE INDEX idx_txiaocx_id_new ON txiaocx USING btree (id) TABLESPACE xiaocx_ts
(1 row)
omm=#6.删除索引
drop index idx_txiaocx_id_new;
\di
omm=# drop index idx_txiaocx_id_new;
DROP INDEX
omm=# \di
List of relations
Schema | Name | Type | Owner | Table | Storage
--------+--------------+-------+-------+----------+---------
public | customer_idx | index | omm | customer |
public | test_pkey | index | omm | test |
(2 rows)
omm=#



