本次课程目的是学习opengauss逻辑结构–索引管理
索引是一个指向表中数据的指针,索引可以用来提高数据库查询性能,但是不恰当的使用将导致数据库性能下降。课程通过对索引的增、删、改、查操作来进一步了解opengauss的索引管理。
1.创建表,在表中创建索引
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=# create index idx_test_testnum on test(testnum);
CREATE INDEX
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)
2.通过hint使用索引
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(# );
'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, 'AAAAAAAADAAAAACREATE 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=# create index customer_idx on customer(ca_address_sk);
CREATE INDEX
omm=#
omm=# EXPLAIN SELECT /*+ indexscan(customer customer_idx ) */ * 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;
ALTER INDEX
omm=# \di
List of relations
Schema | Name | Type | Owner | Table | Storage
--------+----------------------+-------+-------+----------+---------
public | customer_idx | index | omm | customer |
public | idx_test_testnum_new | index | omm | test |
public | test_pkey | index | omm | test |
(3 rows)
4.重建索引
omm=# ALTER INDEX idx_test_testnum_new REBUILD;
REINDEX
omm=# REINDEX INDEX idx_test_testnum_new;
REINDEX
omm=# reindex table test;
REINDEX
5.移动索引到其他表空间
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 ON test USING btree (id) TABLESPACE pg_default
public | test | idx_test_testnum_new | myindex_ts | CREATE INDEX idx_test_testnum_new 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_new ON test USING btree (testnum) TABLESPACE myindex_ts
(1 row)
6.删除索引
omm=# drop index idx_test_testnum_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)
「喜欢这篇文章,您的关注和赞赏是给作者最好的鼓励」
关注作者
【版权声明】本文为墨天轮用户原创内容,转载时必须标注文章的来源(墨天轮),文章链接,文章作者等基本信息,否则作者和墨天轮有权追究责任。如果您发现墨天轮中有涉嫌抄袭或者侵权的内容,欢迎发送邮件至:contact@modb.pro进行举报,并提供相关证据,一经查实,墨天轮将立刻删除相关内容。




