学习openGauss收集统计信息、打印执行计划、垃圾收集和checkpoint
1.创建分区表,并用generate_series(1,N)函数对表插入数据
Create schema tpcds;
CREATE TABLE tpcds.mycustomer_address
(
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)
)
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
);
insert into tpcds.mycustomer_address 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');
insert into tpcds.mycustomer_address values(generate_series(10, 10000));
omm=# Create schema tpcds;
CREATE SCHEMA
omm=# CREATE TABLE tpcds.mycustomer_address
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(# )
omm-# PARTITION BY RANGE(CA_ADDRESS_SK)
omm-# (
omm(# PARTITION p1 VALUES LESS THAN (3000),
omm(# PARTITION p2 VALUES LESS THAN (5000) TABLESPACE example1,
omm(# PARTITION p3 VALUES LESS THAN (MAXVALUE) TABLESPACE example2
omm(# );
CREATE TABLE
omm=# insert into tpcds.mycustomer_address 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=# insert into tpcds.mycustomer_address values(generate_series(10, 10000));
INSERT 0 9991
2.收集表统计信息
select relname, relpages, reltuples from pg_class where relname = 'mycustomer_address';
analyze VERBOSE tpcds.mycustomer_address;
select relname, relpages, reltuples from pg_class where relname = 'mycustomer_address';
omm=# select relname, relpages, reltuples from pg_class where relname = 'mycustomer_address'; relname | relpages | reltuples ------------------+----------+----------- mycustomer_address | 56 | 9991 (1 row) omm=# omm=# analyze VERBOSE tpcds.mycustomer_address; INFO: analyzing "tpcds.mycustomer_address"(gaussdb pid=1) INFO: ANALYZE INFO : "mycustomer_address": scanned 17 of 17 pages, containing 2990 live rows and 0 dead rows; 2990 rows in sample, 2990 estimated total rows(gaussdb pid=1) INFO: ANALYZE INFO : "mycustomer_address": scanned 11 of 11 pages, containing 2000 live rows and 0 dead rows; 2000 rows in sample, 2000 estimated total rows(gaussdb pid=1) INFO: ANALYZE INFO : "mycustomer_address": scanned 28 of 28 pages, containing 5001 live rows and 0 dead rows; 5001 rows in sample, 5001 estimated total rows(gaussdb pid=1) ANALYZE omm=# omm=# select relname, relpages, reltuples from pg_class where relname = 'mycustomer_address'; relname | relpages | reltuples ------------------+----------+----------- mycustomer_address | 56 | 9991 (1 row)
3.显示简单查询的执行计划;建立索引并显示有索引条件的执行计划
SET explain_perf_mode=normal;
EXPLAIN SELECT * FROM tpcds.mycustomer_address;
create index mycustomer_address_idx on tpcds.mycustomer_address(ca_address_sk);
EXPLAIN SELECT * FROM tpcds.mycustomer_address WHERE ca_address_sk<100;
omm=# SET explain_perf_mode=normal;
SET
omm=# EXPLAIN SELECT * FROM tpcds.mycustomer_address;
QUERY PLAN
-----------------------------------------------------------------------------------------
Partition Iterator (cost=0.00..155.91 rows=9991 width=788)
Iterations: 3
-> Partitioned Seq Scan on mycustomer_address (cost=0.00..155.91 rows=9991 width=788)
Selected Partitions: 1..3
(4 rows)
omm=# create index mycustomer_address_idx on tpcds.mycustomer_address(ca_address_sk);
CREATE INDEX
omm=# EXPLAIN SELECT * FROM tpcds.mycustomer_address WHERE ca_address_sk<100;
QUERY PLAN
------------------------------------------------------------------------------------------------
Index Scan using mycustomer_address_idx on mycustomer_address (cost=0.00..9.84 rows=91 width=788)
Index Cond: (ca_address_sk < 100)
(2 rows)
4.更新表数据,并做垃圾收集
update tpcds.mycustomer_address set ca_address_sk = ca_address_sk + 1 where ca_address_sk <100;
VACUUM (VERBOSE, ANALYZE) tpcds.mycustomer_address;
omm=# update tpcds.mycustomer_address set ca_address_sk = ca_address_sk + 1 where ca_address_sk <100; UPDATE 90 omm=# VACUUM (VERBOSE, ANALYZE) tpcds.mycustomer_address; INFO: vacuuming "tpcds.mycustomer_address"(gaussdb pid=1) INFO: index "mycustomer_address_idx" now contains 3080 row versions in 31 pages(gaussdb pid=1) DETAIL: 0 index row versions were removed. 0 index pages have been deleted, 0 are currently reusable. CPU 0.00s/0.00u sec elapsed 0.00 sec. INFO: "mycustomer_address": found 0 removable, 3080 nonremovable row versions in 17 out of 17 pages(gaussdb pid=1) DETAIL: 90 dead row versions cannot be removed yet. There were 0 unused item pointers. 0 pages are entirely empty. CPU 0.00s/0.00u sec elapsed 0.00 sec. INFO: vacuuming "tpcds.mycustomer_address"(gaussdb pid=1) INFO: index "mycustomer_address_idx" now contains 2000 row versions in 31 pages(gaussdb pid=1) DETAIL: 0 index row versions were removed. 0 index pages have been deleted, 0 are currently reusable. CPU 0.00s/0.00u sec elapsed 0.00 sec. INFO: "mycustomer_address": found 0 removable, 2000 nonremovable row versions in 11 out of 11 pages(gaussdb pid=1) DETAIL: 0 dead row versions cannot be removed yet. There were 0 unused item pointers. 0 pages are entirely empty. CPU 0.00s/0.00u sec elapsed 0.00 sec. INFO: vacuuming "tpcds.mycustomer_address"(gaussdb pid=1) INFO: index "mycustomer_address_idx" now contains 5001 row versions in 31 pages(gaussdb pid=1) DETAIL: 0 index row versions were removed. 0 index pages have been deleted, 0 are currently reusable. CPU 0.00s/0.00u sec elapsed 0.00 sec. INFO: "mycustomer_address": found 0 removable, 5001 nonremovable row versions in 28 out of 28 pages(gaussdb pid=1) DETAIL: 0 dead row versions cannot be removed yet. There were 0 unused item pointers. 0 pages are entirely empty. CPU 0.00s/0.00u sec elapsed 0.00 sec. INFO: scanned index "mycustomer_address_idx" to remove 0.000000 invisible rows(gaussdb pid=1) DETAIL: CPU 0.00s/0.00u sec elapsed 0.00 sec. INFO: analyzing "tpcds.mycustomer_address"(gaussdb pid=1) INFO: ANALYZE INFO : "mycustomer_address": scanned 17 of 17 pages, containing 2990 live rows and 90 dead rows; 2990 rows in sample, 2990 estimated total rows(gaussdb pid=1) INFO: ANALYZE INFO : "mycustomer_address": scanned 11 of 11 pages, containing 2000 live rows and 0 dead rows; 2000 rows in sample, 2000 estimated total rows(gaussdb pid=1) INFO: ANALYZE INFO : "mycustomer_address": scanned 28 of 28 pages, containing 5001 live rows and 0 dead rows; 5001 rows in sample, 5001 estimated total rows(gaussdb pid=1) VACUUM
5.清理数据
drop schema tpcds cascade;
「喜欢这篇文章,您的关注和赞赏是给作者最好的鼓励」
关注作者
【版权声明】本文为墨天轮用户原创内容,转载时必须标注文章的来源(墨天轮),文章链接,文章作者等基本信息,否则作者和墨天轮有权追究责任。如果您发现墨天轮中有涉嫌抄袭或者侵权的内容,欢迎发送邮件至:contact@modb.pro进行举报,并提供相关证据,一经查实,墨天轮将立刻删除相关内容。




