暂无图片
暂无图片
暂无图片
暂无图片
暂无图片

openGauss每日一练第10天 | 学习心得体会【少安】

原创 严少安 2021-12-16
720

学习目标

学习openGauss分区表索引

课程学习

连接数据库

#第一次进入等待15秒 
#数据库启动中... 
su - omm 
gsql -r

1.创建分区表索引

CREATE TABLESPACE example1 RELATIVE LOCATION 'tablespace1/tablespace_1'; CREATE TABLESPACE example2 RELATIVE LOCATION 'tablespace2/tablespace_2'; CREATE TABLESPACE example3 RELATIVE LOCATION 'tablespace3/tablespace_3'; CREATE TABLESPACE example4 RELATIVE LOCATION 'tablespace4/tablespace_4'; create schema tpcds; CREATE TABLE tpcds.customer_address_p1 ( CA_ADDRESS_SK INTEGER NOT NULL, CA_ADDRESS_ID CHAR(16) NOT NULL, CA_STREET_NUMBER CHAR(10) , CA_STREET_NAME VARCHAR(60) , CA_STREET_TYPE CHAR(15) , CA_SUITE_NUMBER CHAR(10) , CA_CITY VARCHAR(60) , CA_COUNTY VARCHAR(30) , CA_STATE CHAR(2) , CA_ZIP CHAR(10) , CA_COUNTRY VARCHAR(20) , CA_GMT_OFFSET DECIMAL(5,2) , CA_LOCATION_TYPE CHAR(20) ) PARTITION BY RANGE(CA_ADDRESS_SK) ( PARTITION p1 VALUES LESS THAN (3000), PARTITION p2 VALUES LESS THAN (5000) TABLESPACE example1, PARTITION p3 VALUES LESS THAN (MAXVALUE) TABLESPACE example2 );

–创建分区表索引ds_customer_address_p1_index1,不指定索引分区的名称
CREATE INDEX ds_customer_address_p1_index1 ON tpcds.customer_address_p1(CA_ADDRESS_SK) LOCAL;
–创建分区表索引ds_customer_address_p1_index2,并指定索引分区的名称。
CREATE INDEX ds_customer_address_p1_index2 ON
tpcds.customer_address_p1(CA_ADDRESS_SK) LOCAL
(
PARTITION CA_ADDRESS_SK_index1,
PARTITION CA_ADDRESS_SK_index2 TABLESPACE example3,
PARTITION CA_ADDRESS_SK_index3 TABLESPACE example4
);
–创建GLOBAL分区索引
CREATE INDEX ds_customer_address_p1_index3 ON tpcds.customer_address_p1(CA_ADDRESS_ID) GLOBAL;
–不指定关键字,默认创建GLOBAL分区索引
CREATE INDEX ds_customer_address_p1_index4 ON tpcds.customer_address_p1(CA_ADDRESS_ID);

10_1.jpg

–查看索引信息
\d+ tpcds.customer_address_p1;
select * from pg_indexes where tablename = ‘customer_address_p1’;
select * from pg_partition;

10_2.jpg

2.修改分区表索引定义–修改分区表索引CA_ADDRESS_SK_index2的表空间为example1
ALTER INDEX tpcds.ds_customer_address_p1_index2 MOVE PARTITION
CA_ADDRESS_SK_index2 TABLESPACE example1;
–修改分区表索引CA_ADDRESS_SK_index3的表空间为example2
ALTER INDEX tpcds.ds_customer_address_p1_index2 MOVE PARTITION
CA_ADDRESS_SK_index3 TABLESPACE example2;
–重命名分区表索引
ALTER INDEX tpcds.ds_customer_address_p1_index2 RENAME PARTITION
CA_ADDRESS_SK_index1 TO CA_ADDRESS_SK_index4;

3.重建索引分区
–重建单个索引分区
reindex index tpcds.ds_customer_address_p1_index1 PARTITION p1_ca_address_sk_idx;
–重建分区上的所有索引
reindex table tpcds.customer_address_p1 PARTITION p1;

4.删除索引
DROP INDEX tpcds.ds_customer_address_p1_index1;
DROP INDEX tpcds.ds_customer_address_p1_index2;
DROP INDEX tpcds.ds_customer_address_p1_index3;
DROP INDEX tpcds.ds_customer_address_p1_index4;

10_3.jpg

课程作业

1.创建范围分区表products, 为表创建分区表索引1,不指定索引分区的名称,创建分区表索引2,并指定索引分区的名称,创建GLOBAL分区索引3

-- 1. create table products ( c1 int, c2 char(2) ) partition by range (c1) ( partition p0 values less than (10), partition p1 values less than (20) ); create index idx1 on products(c1) local; create index idx2 on products(c1) local ( partition idx_c1_p0, partition idx_c1_p1 ); create index idx3 on products(c2) global; \d+ products

10_4.jpg

2.在分区表索引1上,修改分区表索引的表空间,重命名分区表索引

-- 2. create tablespace tspc_idx1 relative location 'tablespace1/tspc_idx1'; create tablespace tspc_idx2 relative location 'tablespace1/tspc_idx2'; alter index idx1 move partition p0_c1_idx tablespace tspc_idx1; alter index idx1 move partition p1_c1_idx tablespace tspc_idx2; alter index idx1 rename partition p0_c1_idx to p0_c1_idx_1; \d+ products

3.在分区表索引2上,重建单个索引分区和分区上的所有索引

-- 3. reindex index idx2 partition idx_c1_p0; reindex table products partition p0;

10_5.jpg

4.使用\d+、系统视图pg_indexes和pg_partition查看索引信息

-- 4. \d+ products select * from pg_indexes where tablename = 'products'; select * from pg_partition;

10_6.jpg

5.删除索引、表和表空间

-- 5. drop index idx1, idx2, idx3; drop table products; drop tablespace tspc_idx1; drop tablespace tspc_idx2;

学习心得

本节内容略微复杂,需要结合前两节的知识点综合运用。

参考文档

openGauss每日一练 | by 少安 | 汇总


松鼠镇楼,按时打卡
songshu1.jpg

「喜欢这篇文章,您的关注和赞赏是给作者最好的鼓励」
关注作者
【版权声明】本文为墨天轮用户原创内容,转载时必须标注文章的来源(墨天轮),文章链接,文章作者等基本信息,否则作者和墨天轮有权追究责任。如果您发现墨天轮中有涉嫌抄袭或者侵权的内容,欢迎发送邮件至:contact@modb.pro进行举报,并提供相关证据,一经查实,墨天轮将立刻删除相关内容。

文章被以下合辑收录

评论