学习目标
掌握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;
课程作业
1.创建表,在表中创建索引
root@modb:~# su - omm
omm@modb:~$ gsql -r
gsql ((openGauss 3.0.0 build 02c14696) compiled at 2022-04-01 18:12:00 commit 0 last mr )
Non-SSL connection (SSL connection is recommended when requiring high-security)
Type "help" for help.
omm=# CREATE TABLE customer
omm-# (
omm(# omm(# ca_address_sk integer NOT NULL ,
omm(# ca_address_id character(16),
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=# \d customer
Table "public.customer"
Column | Type | Modifiers
------------------+-----------------------+-----------
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) |
omm=# create index customer_idx on customer(ca_address_sk);
CREATE INDEX
omm=# \d customer
Table "public.customer"
Column | Type | Modifiers
------------------+-----------------------+-----------
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) |
Indexes:
"customer_idx" btree (ca_address_sk) TABLESPACE pg_default
omm=# \di customer_idx
List of relations
Schema | Name | Type | Owner | Table | Storage
--------+--------------+-------+-------+----------+---------
public | customer_idx | index | omm | customer |
(1 row)
omm=#


2.通过hint使用索引
omm=# explain select * from customer where ca_address_sk <100;
QUERY PLAN
------------------------------------------------------------
Seq Scan on customer (cost=0.00..11.25 rows=33 width=788)
Filter: (ca_address_sk < 100)
(2 rows)
omm=# EXPLAIN SELECT /*+ indexscan(customer customer_idx ) */
omm-# * FROM customer WHERE ca_address_sk<100;
omm=# QUERY PLAN
---------------------------------------------------------------------------------
[Bypass]
Index Scan using customer_idx on customer (cost=0.00..44.83 rows=33 width=788)
Index Cond: (ca_address_sk < 100)
(3 rows)
omm=# 
3.rename索引
omm=# \di customer_idx
List of relations
Schema | Name | Type | Owner | Table | Storage
--------+--------------+-------+-------+----------+---------
public | customer_idx | index | omm | customer |
(1 row)
omm=# alter index customer_idx rename to customer_idx_nuwname;
omm=# ALTER INDEX
omm=# \di customer_idx
No matching relations found.
omm=# \di customer_idx_nuwname
omm=# List of relations
Schema | Name | Type | Owner | Table | Storage
--------+----------------------+-------+-------+----------+---------
public | customer_idx_nuwname | index | omm | customer |
(1 row)
omm=#
4.重建索引
omm=# alter index customer_idx_nuwname rebuild;
REINDEX
omm=# REINDEX INDEX customer_idx_nuwname ;
omm=# REINDEX
omm=# reindex table customer;
REINDEX
omm=# 
5.移动索引到其他表空间
omm=# create tablespace myindex_ts relative location 'tablespace/myindex_ts1';
CREATE TABLESPACE
omm=# select * from pg_indexes where tablename='customer';
schemaname | tablename | indexname | tablespace | indexdef
------------+-----------+----------------------+------------+---------------------------------------------------------------------------------------------
----
public | customer | customer_idx_nuwname | | CREATE INDEX customer_idx_nuwname ON customer USING btree (ca_address_sk) TABLESPACE pg_defa
ult
(1 row)
omm=# \x
Expanded display is on.
omm=# select * from pg_indexes where tablename='customer';
-[ RECORD 1 ]-----------------------------------------------------------------------------------------------
schemaname | public
tablename | customer
indexname | customer_idx_nuwname
tablespace |
indexdef | CREATE INDEX customer_idx_nuwname ON customer USING btree (ca_address_sk) TABLESPACE pg_default
omm=# select * from pg_indexes where indexname='customer_idx_nuwname';
-[ RECORD 1 ]-----------------------------------------------------------------------------------------------
schemaname | public
tablename | customer
indexname | customer_idx_nuwname
tablespace |
indexdef | CREATE INDEX customer_idx_nuwname ON customer USING btree (ca_address_sk) TABLESPACE pg_default
omm=# alter index customer_idx_nuwname set tablespace myindex_ts;
ALTER INDEX
omm=# select * from pg_indexes where tablename='customer';
-[ RECORD 1 ]-----------------------------------------------------------------------------------------------
schemaname | public
tablename | customer
indexname | customer_idx_nuwname
tablespace | myindex_ts
indexdef | CREATE INDEX customer_idx_nuwname ON customer USING btree (ca_address_sk) TABLESPACE myindex_ts
omm=# select * from pg_indexes where indexname='customer_idx_nuwname';
-[ RECORD 1 ]-----------------------------------------------------------------------------------------------
schemaname | public
tablename | customer
indexname | customer_idx_nuwname
tablespace | myindex_ts
indexdef | CREATE INDEX customer_idx_nuwname ON customer USING btree (ca_address_sk) TABLESPACE myindex_ts
omm=# 
6.删除索引
omm=# \di
List of relations
Schema | Name | Type | Owner | Table | Storage
--------+----------------------+-------+-------+----------+---------
public | customer_idx_nuwname | index | omm | customer |
public | idx_test_testnum | index | omm | test |
public | test_pkey | index | omm | test |
(3 rows)
omm=# drop index customer_idx_nuwname ;
DROP 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=# drop index idx_test_testnum ;
DROP INDEX
omm=# \di
omm=# List of relations
Schema | Name | Type | Owner | Table | Storage
--------+-----------+-------+-------+-------+---------
public | test_pkey | index | omm | test |
(1 row)
omm=# 
「喜欢这篇文章,您的关注和赞赏是给作者最好的鼓励」
关注作者
【版权声明】本文为墨天轮用户原创内容,转载时必须标注文章的来源(墨天轮),文章链接,文章作者等基本信息,否则作者和墨天轮有权追究责任。如果您发现墨天轮中有涉嫌抄袭或者侵权的内容,欢迎发送邮件至:contact@modb.pro进行举报,并提供相关证据,一经查实,墨天轮将立刻删除相关内容。




