学习目标
掌握openGauss DBMS索引的管理:创建索引、删除索引、查询索引的信息、修改索引的信息。
课程学习
索引是一个指向表中数据的指针。一个数据库中的索引与一本书的索引目录是非常相似的。
索引可以用来提高数据库查询性能,但是不恰当的使用将导致数据库性能下降。
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
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;
3.rename索引
ALTER INDEX idx_test_testnum RENAME TO idx_test_testnum_new;
4.重建索引
--重建一个单独索引
ALTER INDEX idx_test_testnum_new REBUILD;
REINDEX INDEX idx_test_testnum_new;
--重建所有索引
reindex table test;
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';
- 删除索引
--执行下面的命令,删除表test上的索引idx_test_testnum_new:
drop index idx_test_testnum_new;
课程作业
准备
su - omm
gsql -r
-- 创建tablespace test01_tbs;
omm=# create tablespace test01_tbs relative location 'tablespaces/test01_tbs';
CREATE TABLESPACE
omm=# create tablespace test02_tbs relative location 'tablespaces/test02_tbs';
CREATE TABLESPACE
1.创建表,在表中创建索引
omm=# create table test01(id serial primary key, num serial, remark varchar(200));
NOTICE: CREATE TABLE will create implicit sequence "test01_id_seq" for serial column "test01.id"
NOTICE: CREATE TABLE will create implicit sequence "test01_num_seq" for serial column "test01.num"
NOTICE: CREATE TABLE / PRIMARY KEY will create implicit index "test01_pkey" for table "test01"
CREATE TABLE
-- 为num 创建索引名称为 idx_mum , 表空间位于 test01_tbs
omm=# create index idx_num on test01(num) tablespace test01_tbs;
CREATE INDEX
-- 查看当前表中的索引
omm=# \di
List of relations
Schema | Name | Type | Owner | Table | Storage
--------+-------------+-------+-------+--------+---------
public | idx_num | index | omm | test01 |
public | test01_pkey | index | omm | test01 |
(2 rows)
-- 插入一些数据
omm=# insert into test01 (remark) values ('ssssss');
INSERT 0 1
omm=# insert into test01 (remark) values ('ssssss');
INSERT 0 1
omm=# insert into test01 (remark) values ('ssssss');
INSERT 0 1
omm=# insert into test01 (remark) values ('ssssss');
INSERT 0 1
omm=# insert into test01 (remark) values ('sssss11s');
INSERT 0 1
omm=# insert into test01 (remark) values ('sssss1s');21s');
INSERT 0 1
-- 查询表中的数据
omm=# select * from test01;
id | num | remark
----+-----+----------
3 | 3 |
4 | 3 |
5 | 3 |
6 | 3 |
7 | 3 |
8 | 3 |
9 | 3 |
10 | 4 | test
11 | 5 | ssssss
12 | 6 | ssssss
13 | 7 | ssssss
14 | 8 | ssssss
15 | 9 | sssss11s
16 | 10 | sssss21s
(14 rows)
2.通过hint使用索引
-- 不通过 hint ,可以看出默认走了idx_num 的索引
omm=# explain select * from test01 where num=7;
QUERY PLAN
------------------------------------------------------------------------
[Bypass]
Index Scan using idx_num on test01 (cost=0.00..8.27 rows=1 width=426)
Index Cond: (num = 7)
(3 rows)
-- 通过hint 走索引 idx_num
omm=# explain select /*+ indexscan(test01 idx_num) */ * from test01 where num = 7;
QUERY PLAN
------------------------------------------------------------------------
[Bypass]
Index Scan using idx_num on test01 (cost=0.00..8.27 rows=1 width=426)
Index Cond: (num = 7)
(3 rows)
3.rename索引
-- 将idx_num 重命名为 idx_num01
omm=# alter index idx_num rename to idx_num01;
ALTER INDEX
-- 查询索引,可以看到名称已经更改为 idx_num01;
omm=# \di
List of relations
Schema | Name | Type | Owner | Table | Storage
--------+-------------+-------+-------+--------+---------
public | idx_num01 | index | omm | test01 |
public | test01_pkey | index | omm | test01 |
(2 rows)
4.重建索引
-- 重建指定的索引 idx_num01
omm=# alter index idx_num01 rebuild;
REINDEX
-- 重建test01 库中所有的索引
omm=# reindex table test01;
REINDEX
5.移动索引到其他表空间
-- 查询当前idx_num01 的表空间,可以看到当前表空间为 test01_tbs
omm=# select * from pg_indexes where indexname = 'idx_num01';
schemaname | tablename | indexname | tablespace | indexdef
------------+-----------+-----------+------------+--------------------------------------------------------------------------
public | test01 | idx_num01 | test01_tbs | CREATE INDEX idx_num01 ON test01 USING btree (num) TABLESPACE test01_tbs
(1 row)
-- 将idx_num01 的表空间挪动到 test02_tbs
omm=# alter index idx_num01 set tablespace test02_tbs ;
ALTER INDEX
-- 再次查看索引详情,发现 idx_num01的 表空间已经变更为 test02_tbs
omm=# select * from pg_indexes where indexname ='idx_num01';
schemaname | tablename | indexname | tablespace | indexdef
------------+-----------+-----------+------------+--------------------------------------------------------------------------
public | test01 | idx_num01 | test02_tbs | CREATE INDEX idx_num01 ON test01 USING btree (num) TABLESPACE test02_tbs
(1 row)
6.删除索引
-- 删除索引 idx_num01
drop index idx_num01;
-- 查看当前表的索引,发现只剩pk
List of relations
Schema | Name | Type | Owner | Table | Storage
--------+-------------+-------+-------+--------+---------
public | test01_pkey | index | omm | test01 |
(1 row)
-- 此时再次执行 explain 查看sql执行计划,发现变为全表扫
omm=# explain select * from test01 where num=7;
QUERY PLAN
--------------------------------------------------------
Seq Scan on test01 (cost=0.00..1.18 rows=1 width=426)
Filter: (num = 7)
(2 rows)
「喜欢这篇文章,您的关注和赞赏是给作者最好的鼓励」
关注作者
【版权声明】本文为墨天轮用户原创内容,转载时必须标注文章的来源(墨天轮),文章链接,文章作者等基本信息,否则作者和墨天轮有权追究责任。如果您发现墨天轮中有涉嫌抄袭或者侵权的内容,欢迎发送邮件至:contact@modb.pro进行举报,并提供相关证据,一经查实,墨天轮将立刻删除相关内容。




