第十七课
17.1 第17天 | openGauss逻辑结构:索引管理
学习目标
掌握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’;
6.删除索引
–执行下面的命令,删除表test上的索引idx_test_testnum_new:
drop index idx_test_testnum_new;
课程作业
1.创建表,在表中创建索引
omm=# 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=# omm=# --查看索引 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=# omm=# CREATE TABLE customer omm-# ( --测试准备,创建表customer,并插入数据 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(# omm(# ca_city character varying(60) , ca_county character varying(30) , omm(# ca_state character(2) , omm(# omm(# ca_zip character(10) , 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=# omm=# --创建索引 omm=# omm=# create index customer_idx on customer(ca_address_sk); CREATE INDEX
复制
2.通过hint使用索引
omm=# --通过hint强制使用索引,查看执行计划 omm=# 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)
复制
3.rename索引
omm=# ALTER INDEX idx_test_testnum RENAME TO idx_test_testnum_new; omm=# ALTER INDEX
复制
4.重建索引
omm=# --重建一个单独索引 omm=# ALTER INDEX idx_test_testnum_new REBUILD; REINDEX omm=# omm=# REINDEX INDEX idx_test_testnum_new; REINDEX omm=# --重建所有索引 omm=# reindex table test; REINDEX
复制
5.移动索引到其他表空间
omm=# omm=# --创建表空间myindex_ts: CREATE TABLESPACE myindex_ts RELATIVE LOCATION 'tablespace/myindex_ts1'; CREATE TABLESPACE omm=# omm=# --将索引idx_test_testnum_new移动到表空间myindex_ts: omm=# ALTER INDEX idx_test_testnum_new SET TABLESPACE myindex_ts; ALTER INDEX omm=# omm=# --查看索引所在的表空间 omm=# select * from pg_indexes where tablename = 'test'; schemaname | tablename | indexname | tablespace | indexdef ------------+-----------+----------------------+------------+------------------------------------ --------------------------------------------------- public | test | test_pkey | | CREATE UNIQUE INDEX test_pkey ON te st USING btree (id) TABLESPACE pg_default public | test | idx_test_testnum_new | myindex_ts | CREATE INDEX idx_test_testnum_new O N test USING btree (testnum) TABLESPACE myindex_ts (2 rows) omm=# --或 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_new O N test USING btree (testnum) TABLESPACE myindex_ts (1 row)
复制
6.删除索引
omm=# --执行下面的命令,删除表test上的索引idx_test_testnum_new: omm=# omm=# drop index idx_test_testnum_new; DROP INDEX omm=#
复制