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

(openGauss每日一练第 19天):openGauss收集统计信息、打印执行计划、垃圾收集和checkpoint

原创 junzibuyuantian 恩墨学院 2021-12-20
350

1.准备数据

--使用gsql登录openGauss root@modb:~# su - omm omm@modb:~$ gsql -r gsql ((openGauss 2.0.0 build 78689da9) compiled at 2021-03-31 21:03:52 commit 0 last mr ) Non-SSL connection (SSL connection is recommended when requiring high-security) Type "help" for help. omm=# --创建用户 omm=# Create schema tpcds; CREATE SCHEMA --创建表 CREATE TABLE tpcds.customer_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) ); CREATE TABLE --插入测试数据 insert into tpcds.customer_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 0 3 --使用序列的generate_series(1,N)函数对表插入数据 omm=# insert into tpcds.customer_address values(generate_series(10, 10000)); INSERT 0 9991

2.收集统计信息

--查看系统表中表的统计信息 omm=# select relname, relpages, reltuples from pg_class where relname = 'customer_address'; relname | relpages | reltuples ------------------+----------+----------- customer_address | 0 | 0 (1 row) --使用ANALYZE VERBOSE语句更新统计信息,并输出表的相关信息 omm=# analyze VERBOSE tpcds.customer_address; INFO: analyzing "tpcds.customer_address"(gaussdb pid=1) INFO: ANALYZE INFO : "customer_address": scanned 55 of 55 pages, containing 9994 live rows and 0 dead rows; 9994 rows in sample, 9994 estimated total rows(gaussdb pid=1) ANALYZE --查看系统表中表的统计信息 omm=# select relname, relpages, reltuples from pg_class where relname = 'customer_address'; relname | relpages | reltuples ------------------+----------+----------- customer_address | 55 | 9994 (1 row)

3.打印执行计划

--使用默认的打印格式 omm=# SET explain_perf_mode=normal; SET --显示表简单查询的执行计划 omm=# EXPLAIN SELECT * FROM tpcds.customer_address; QUERY PLAN ----------------------------------------------------------------------- Seq Scan on customer_address (cost=0.00..154.94 rows=9994 width=151) (1 row) --以JSON格式输出的执行计划(explain_perf_mode为normal时) omm=# EXPLAIN(FORMAT JSON) SELECT * FROM tpcds.customer_address; QUERY PLAN -------------------------------------------- [ + { + "Plan": { + "Node Type": "Seq Scan", + "Relation Name": "customer_address",+ "Alias": "customer_address", + "Startup Cost": 0.00, + "Total Cost": 154.94, + "Plan Rows": 9994, + "Plan Width": 151 + } + } + ] (1 row) --禁止开销估计的执行计划 omm=# EXPLAIN(COSTS FALSE)SELECT * FROM tpcds.customer_address; QUERY PLAN ------------------------------ Seq Scan on customer_address (1 row) --带有聚集函数查询的执行计划 omm=# EXPLAIN SELECT SUM(ca_address_sk) FROM tpcds.customer_address WHERE ca_address_sk<100; QUERY PLAN ------------------------------------------------------------------------- Aggregate (cost=180.16..180.17 rows=1 width=12) -> Seq Scan on customer_address (cost=0.00..179.93 rows=94 width=4) Filter: (ca_address_sk < 100) (3 rows) --有索引条件的执行计划 omm=# create index customer_address_idx on tpcds.customer_address(ca_address_sk); CREATE INDEX omm=# EXPLAIN SELECT * FROM tpcds.customer_address WHERE ca_address_sk<100; QUERY PLAN ------------------------------------------------------------------------------------------------ [Bypass] Index Scan using customer_address_idx on customer_address (cost=0.00..9.90 rows=94 width=151) Index Cond: (ca_address_sk < 100) (3 rows)

4.垃圾收集

--VACUUM回收表或B-Tree索引中已经删除的行所占据的存储空间 omm=# update tpcds.customer_address set ca_address_sk = ca_address_sk + 1 where ca_address_sk <100; UPDATE 93 omm=# VACUUM (VERBOSE, ANALYZE) tpcds.customer_address; INFO: vacuuming "tpcds.customer_address"(gaussdb pid=1) INFO: index "customer_address_idx" now contains 10087 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: "customer_address": found 0 removable, 10087 nonremovable row versions in 55 out of 55 pages(gaussdb pid=1) DETAIL: 93 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: analyzing "tpcds.customer_address"(gaussdb pid=1) INFO: ANALYZE INFO : "customer_address": scanned 55 of 55 pages, containing 9994 live rows and 93 dead rows; 9994 rows in sample, 9994 estimated total rows(gaussdb pid=1) VACUUM

5.事务日志检查点

--检查点?-HECKPOINT)是一个事务日志中的点,所有数据文件都在该点被更新以反映日志中的信息,所有数据文件都将被刷新到磁盘 omm=# CHECKPOINT; CHECKPOINT

6.清理数据

omm=# drop schema tpcds cascade; NOTICE: drop cascades to table tpcds.customer_address DROP SCHEMA

练习:
1.创建分区表,并用generate_series(1,N)函数对表插入数据

omm=# create schema junzi; CREATE SCHEMA omm=# CREATE TABLE junzi.products ( CA_ADDRESS_SK INTEGER NOT NULL, CA_ADDRESS_ID CHAR(16) 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), PARTITION p3 VALUES LESS THAN (MAXVALUE) ); CREATE TABLE insert into junzi.products 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 0 3 insert into junzi.products values(generate_series(10, 10000));

2.收集表统计信息

--查看系统表中表的统计信息 omm=# select relname, relpages, reltuples from pg_class where relname = 'customer_address'; relname | relpages | reltuples ---------+----------+----------- (0 rows) --使用ANALYZE VERBOSE语句更新统计信息,并输出表的相关信息 omm=# analyze VERBOSE junzi.products; INFO: analyzing "junzi.products"(gaussdb pid=1) INFO: ANALYZE INFO : "products": scanned 17 of 17 pages, containing 2993 live rows and 0 dead rows; 2993 rows in sample, 2993 estimated total rows(gaussdb pid=1) INFO: ANALYZE INFO : "products": 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 : "products": 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=# select relname, relpages, reltuples from pg_class where relname = 'customer_address'; relname | relpages | reltuples ---------+----------+----------- (0 rows)

3.显示简单查询的执行计划;建立索引并显示有索引条件的执行计划

omm=# EXPLAIN SELECT * FROM junzi.products; -> Partitioned Seq Scan on products (cost=0.00..155.94 rows=9994 width=151) Selected Partitions: 1..3 (4 rows) omm=# QUERY PLAN --------------------------------------------------------------------------------- Partition Iterator (cost=0.00..155.94 rows=9994 width=151) Iterations: 3 omm=# CREATE INDEX products_index1 ON junzi.products(CA_ADDRESS_SK); CREATE INDEX omm=# EXPLAIN SELECT * FROM junzi.products WHERE ca_address_sk<100; QUERY PLAN ----------------------------------------------------------------------------------- Index Scan using products_index1 on products (cost=0.00..9.90 rows=94 width=151) Index Cond: (ca_address_sk < 100) (2 rows)

4.更新表数据,并做垃圾收集

omm=# update junzi.products set ca_address_sk = ca_address_sk + 1 where ca_address_sk <100; UPDATE 93 omm=# VACUUM (VERBOSE, ANALYZE) junzi.products; INFO: vacuuming "junzi.products"(gaussdb pid=1) INFO: index "products_index1" now contains 3086 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: "products": found 0 removable, 3086 nonremovable row versions in 17 out of 17 pages(gaussdb pid=1) DETAIL: 93 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 "junzi.products"(gaussdb pid=1) INFO: index "products_index1" 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: "products": 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 "junzi.products"(gaussdb pid=1) INFO: index "products_index1" 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: "products": 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 "products_index1" to remove 0.000000 invisible rows(gaussdb pid=1) DETAIL: CPU 0.00s/0.00u sec elapsed 0.00 sec. INFO: analyzing "junzi.products"(gaussdb pid=1) INFO: ANALYZE INFO : "products": scanned 17 of 17 pages, containing 2993 live rows and 93 dead rows; 2993 rows in sample, 2993 estimated total rows(gaussdb pid=1) INFO: ANALYZE INFO : "products": 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 : "products": 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.清理数据

omm=# drop schema junzi; ERROR: cannot drop schema junzi because other objects depend on it DETAIL: table junzi.products depends on schema junzi HINT: Use DROP ... CASCADE to drop the dependent objects too. omm=# drop schema junzi cascade; NOTICE: drop cascades to table junzi.products DROP SCHEMA
最后修改时间:2021-12-20 00:10:50
「喜欢这篇文章,您的关注和赞赏是给作者最好的鼓励」
关注作者
【版权声明】本文为墨天轮用户原创内容,转载时必须标注文章的来源(墨天轮),文章链接,文章作者等基本信息,否则作者和墨天轮有权追究责任。如果您发现墨天轮中有涉嫌抄袭或者侵权的内容,欢迎发送邮件至:contact@modb.pro进行举报,并提供相关证据,一经查实,墨天轮将立刻删除相关内容。

评论