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

openGauss每日一练第 10天|分区表索引

原创 mimizhejiang 2021-12-10
262

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

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.products ( 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 ); CREATE INDEX ds_products_index1 ON tpcds.products(CA_ADDRESS_SK) LOCAL; CREATE INDEX ds_products_index2 ON tpcds.products(CA_ADDRESS_SK) LOCAL ( PARTITION CA_ADDRESS_SK_index1, PARTITION CA_ADDRESS_SK_index2 TABLESPACE example3, PARTITION CA_ADDRESS_SK_index3 TABLESPACE example4 ); CREATE INDEX ds_products_index3 ON tpcds.products(CA_ADDRESS_ID) GLOBAL; CREATE INDEX ds_products_index4 ON tpcds.products(CA_ADDRESS_ID);

\d+ tpcds.products;
image.png
可以看出系统自动对分区表索引1进行了索引分区的命名

select * from pg_indexes where tablename = 'products';

image.png

select * from pg_partition;

image.png

image.png

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

ALTER INDEX tpcds.ds_products_index1 MOVE PARTITION p1_ca_address_sk_idx TABLESPACE example1; ALTER INDEX tpcds.ds_products_index1 RENAME PARTITION p1_ca_address_sk_idx TO p4_ca_address_sk_idx ;

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

reindex index tpcds.ds_products_index2 PARTITION CA_ADDRESS_SK_index2; reindex table tpcds.products PARTITION p1;

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

select * from pg_indexes where tablename = 'products';

image.png

select * from pg_partition;

image.png
image.png

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

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

评论