0.学习内容与环境进入
学习目标
掌握openGauss DBMS索引的管理:创建索引、删除索引、查询索引的信息、修改索引的信息。
索引是一个指向表中数据的指针。一个数据库中的索引与一本书的索引目录是非常相似的。
索引可以用来提高数据库查询性能,但是不恰当的使用将导致数据库性能下降。
/*+ <plan hint>*/
select /*+ <plan_hint1> <plan_hint2> */ * from t1, (select /*+ <plan_hint3> */ from t2) where 1=1;
-
Hints
Currently, the following hints are supported:- Join order hints (
leading) - Join operation hints, excluding the
semi join,anti join, andunique planhints - Rows hints
- Scan operation hints, supporting only
tablescan,indexscan, andindexonlyscan - Sublink name hints
- Join order hints (
-
Precautions
- Hints do not support
Agg,Sort,Setop, orSubplan.
- Hints do not support
-
查看表约束
`\d <tablename>`
create index <index-name> on <table>(<column-name>);
-
修改表字段默认值
alter table t1 set column <name> default <value>; -
进入环境
su - omm 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.
\l
Name | Owner | Encoding | Collate | Ctype | Access privileges
-----------+-------+----------+---------+-------+-------------------
omm | omm | UTF8 | C | C |
postgres | omm | UTF8 | C | C |
template0 | omm | UTF8 | C | C | =c/omm +
| | | | | omm=CTc/omm
| template1 | omm | UTF8 | C | C | =c/omm +
| | | | | omm=CTc/omm
| (4 rows)
1. 创建表,在表中创建索引
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);
CREATE TABLE
INSERT 0 3
CREATE INDEX
INSERT 0 3
CREATE INDEX
2.通过hint使用索引
hint的语法用 /*+ indexscan*/
EXPLAIN SELECT /*+ indexscan(customer customer_idx ) */
* FROM customer WHERE ca_address_sk<100;
-------------------------------------------------------------------------------
[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索引
ALTER INDEX customer_idx RENAME TO customer_idx_new;
\d 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_new" btree (ca_address_sk) TABLESPACE pg_default
4.重建索引
ALTER INDEX customer_idx_new REBUILD;
REINDEX
REINDEX INDEX customer_idx_new;
5.移动索引到其他表空间
- 创建表空间myindex_ts:
CREATE TABLESPACE myindex_ts RELATIVE LOCATION ‘tablespace/myindex_ts1’;
CREATE TABLESPACE
- 将索引customer_idx_new移动到表空间myindex_ts:
ALTER INDEX customer_idx_new SET TABLESPACE myindex_ts;
- 查看索引所在的表空间
select tablespace from pg_indexes where tablename = 'customer';
tablespace
------------
myindex_ts
(1 row)
------------
myindex_ts
(1 row)
6.删除索引
- 执行下面的命令,删除表test上的索引customer_idx_new:
drop index customer_idx_new;
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) |
最后修改时间:2022-12-11 17:36:52
「喜欢这篇文章,您的关注和赞赏是给作者最好的鼓励」
关注作者
【版权声明】本文为墨天轮用户原创内容,转载时必须标注文章的来源(墨天轮),文章链接,文章作者等基本信息,否则作者和墨天轮有权追究责任。如果您发现墨天轮中有涉嫌抄袭或者侵权的内容,欢迎发送邮件至:contact@modb.pro进行举报,并提供相关证据,一经查实,墨天轮将立刻删除相关内容。




