GaussDB(DWS)性能调优:常见不等值关联转等值关联

举报
譡里个檔 发表于 2022/10/12 10:40:50 2022/10/12
【摘要】 预置条件CREATE TABLE st( zjhm text, -- 证件号码 rzsj timestamptz, -- 入住时间 ldsj timestamptz -- 离店时间);场景1  ABS < interval原始SQLSELECT *FROM st a, st b WHERE abs(a.rzsj-b.rzsj) < interval '10 min'-- 执...

预置条件

CREATE TABLE st(
    zjhm text, -- 证件号码
    rzsj timestamptz, -- 入住时间
    ldsj timestamptz -- 离店时间
);


  • 场景1  ABS < interval

原始SQL

SELECT *
FROM st a, st b 
WHERE abs(a.rzsj-b.rzsj) < interval '10 min'
-- 执行计划
postgres=# EXPLAIN SELECT *
postgres-# FROM st a, st b
postgres-# WHERE abs(a.rzsj-b.rzsj) < interval '10 min'
postgres-# ;
                                     QUERY PLAN
-------------------------------------------------------------------------------------
  id |              operation               | E-rows | E-memory | E-width | E-costs
 ----+--------------------------------------+--------+----------+---------+---------
   1 | ->  Streaming (type: GATHER)         |    300 |          |      96 | 42.18
   2 |    ->  Nested Loop (3,5)             |    300 | 1MB      |      96 | 29.68
   3 |       ->  Streaming(type: BROADCAST) |     90 | 2MB      |      48 | 12.80
   4 |          ->  Seq Scan on st a        |     30 | 1MB      |      48 | 10.10
   5 |       ->  Materialize                |     30 | 16MB     |      48 | 10.15
   6 |          ->  Seq Scan on st b        |     30 | 1MB      |      48 | 10.10

                 Predicate Information (identified by plan id)
 -----------------------------------------------------------------------------
   2 --Nested Loop (3,5)
         Join Filter: (abs(((a.rzsj - b.rzsj))::numeric) < .00694444444444444)


改写SQL

WITH t AS(
    SELECT 
        zjhm,
        rzsj,
        ldsj,
        extract(epoch from rzsj)::numeric AS rzlen,
        interval '10min' as interval,
        extract(epoch from interval '10min')::numeric AS step,
        trunc(rzlen/step)::bigint AS rzmod
    FROM st
)

SELECT
    a.zjhm, a.rzsj, a.ldsj, b.zjhm, b.rzsj, b.ldsj
FROM t a, t b
WHERE a.rzmod = b.rzmod

UNION ALL 

SELECT
    a.zjhm, a.rzsj, a.ldsj, b.zjhm, b.rzsj, b.ldsj
FROM t a, t b
WHERE a.rzmod = b.rzmod + 1
    AND a.rzsj-b.rzsj < a.interval

UNION ALL 

SELECT
    a.zjhm, a.rzsj, a.ldsj, b.zjhm, b.rzsj, b.ldsj
FROM t a, t b
WHERE a.rzmod = b.rzmod - 1
    AND b.rzsj-a.rzsj < a.interval
;

-- 执行计划
                                           QUERY PLAN
-------------------------------------------------------------------------------------------------
  id |                    operation                     | E-rows | E-memory | E-width | E-costs
 ----+--------------------------------------------------+--------+----------+---------+---------
   1 | ->  Streaming (type: GATHER)                     |      9 |          |      96 | 10.04
   2 |    ->  Result                                    |      9 | 1MB      |      96 | 2.04
   3 |       ->  CTE Append(4, 6)                       |      9 | 1MB      |      96 | 2.04
   4 |          ->  Streaming(type: LOCAL GATHER)       |      3 | 2MB      |      18 | 1.03
   5 |             ->  Seq Scan on st  [4, CTE t(1)]    |      1 | 1MB      |      18 | 1.03
   6 |          ->  Append(7, 12, 17)                   |      9 | 1MB      |      96 | 1.01
   7 |             ->  Nested Loop (8,9)                |      3 | 1MB      |      96 | 0.32
   8 |                ->  CTE Scan on t(1) a            |      1 | 1MB      |      56 | 0.02
   9 |                ->  Materialize                   |      3 | 16MB     |      56 | 0.29
  10 |                   ->  Streaming(type: BROADCAST) |      3 | 2MB      |      56 | 0.29
  11 |                      ->  CTE Scan on t(1) b      |      1 | 1MB      |      56 | 0.02
  12 |             ->  Nested Loop (13,14)              |      3 | 1MB      |      96 | 0.33
  13 |                ->  CTE Scan on t(1) a            |      1 | 1MB      |      72 | 0.02
  14 |                ->  Materialize                   |      3 | 16MB     |      56 | 0.29
  15 |                   ->  Streaming(type: BROADCAST) |      3 | 2MB      |      56 | 0.29
  16 |                      ->  CTE Scan on t(1) b      |      1 | 1MB      |      56 | 0.02
  17 |             ->  Nested Loop (18,19)              |      3 | 1MB      |      96 | 0.33
  18 |                ->  CTE Scan on t(1) a            |      1 | 1MB      |      72 | 0.02
  19 |                ->  Materialize                   |      3 | 16MB     |      56 | 0.29
  20 |                   ->  Streaming(type: BROADCAST) |      3 | 2MB      |      56 | 0.29
  21 |                      ->  CTE Scan on t(1) b      |      1 | 1MB      |      56 | 0.02

                      Predicate Information (identified by plan id)
 ---------------------------------------------------------------------------------------
   7 --Nested Loop (8,9)
         Join Filter: (a.rzmod = b.rzmod)
  12 --Nested Loop (13,14)
         Join Filter: (((a.rzsj - b.rzsj) < a."interval") AND (a.rzmod = (b.rzmod + 1)))
  17 --Nested Loop (18,19)
         Join Filter: (((b.rzsj - a.rzsj) < a."interval") AND (a.rzmod = (b.rzmod - 1)))

计划对比


  • 场景2 BETWEEN AND

原始SQL

SELECT a.zjhm, a.rzsj, a.ldsj, b.zjhm, b.rzsj, b.ldsj
FROM st a, st b 
WHERE a.rzsj BETWEEN b.rzsj AND b.ldsj
;

-- 执行计划
                                     QUERY PLAN
-------------------------------------------------------------------------------------
  id |              operation               | E-rows | E-memory | E-width | E-costs
 ----+--------------------------------------+--------+----------+---------+---------
   1 | ->  Streaming (type: GATHER)         |    173 |          |      96 | 36.18
   2 |    ->  Nested Loop (3,5)             |    173 | 1MB      |      96 | 28.18
   3 |       ->  Streaming(type: BROADCAST) |     90 | 2MB      |      48 | 12.80
   4 |          ->  Seq Scan on st a        |     30 | 1MB      |      48 | 10.10
   5 |       ->  Materialize                |     30 | 16MB     |      48 | 10.15
   6 |          ->  Seq Scan on st b        |     30 | 1MB      |      48 | 10.10

          Predicate Information (identified by plan id)
 ----------------------------------------------------------------
   2 --Nested Loop (3,5)
         Join Filter: ((a.rzsj >= b.rzsj) AND (a.rzsj <= b.ldsj))

改写SQL

WITH t AS(
    SELECT 
        zjhm,
        rzsj,
        ldsj,
        extract(epoch from rzsj)::numeric AS rzlen,
        extract(epoch from interval (ldsj-rzsj))::numeric AS step,
        trunc(rzlen/step)::bigint AS rzmod
    FROM st
)

SELECT
    a.zjhm, a.rzsj, a.ldsj, b.zjhm, b.rzsj, b.ldsj
FROM t a, t b
WHERE a.rzmod = b.rzmod
AND a.rzsj BETWEEN b.rzsj AND b.ldsj

UNION ALL 

SELECT
    a.zjhm, a.rzsj, a.ldsj, b.zjhm, b.rzsj, b.ldsj
FROM t a, t b
WHERE a.rzmod = b.rzmod + 1
AND a.rzsj BETWEEN b.rzsj AND b.ldsj

UNION ALL 

SELECT
    a.zjhm, a.rzsj, a.ldsj, b.zjhm, b.rzsj, b.ldsj
FROM t a, t b
WHERE a.rzmod = b.rzmod - 1
AND a.rzsj BETWEEN b.rzsj AND b.ldsj
;

-- 执行计划
                                           QUERY PLAN
-------------------------------------------------------------------------------------------------
  id |                    operation                     | E-rows | E-memory | E-width | E-costs
 ----+--------------------------------------------------+--------+----------+---------+---------
   1 | ->  Streaming (type: GATHER)                     |      9 |          |      96 | 10.06
   2 |    ->  Result                                    |      9 | 1MB      |      96 | 2.06
   3 |       ->  CTE Append(4, 6)                       |      9 | 1MB      |      96 | 2.06
   4 |          ->  Streaming(type: LOCAL GATHER)       |      3 | 2MB      |      18 | 1.04
   5 |             ->  Seq Scan on st  [4, CTE t(1)]    |      1 | 1MB      |      18 | 1.04
   6 |          ->  Append(7, 12, 17)                   |      9 | 1MB      |      96 | 1.02
   7 |             ->  Nested Loop (8,9)                |      3 | 1MB      |      96 | 0.33
   8 |                ->  CTE Scan on t(1) a            |      1 | 1MB      |      56 | 0.02
   9 |                ->  Materialize                   |      3 | 16MB     |      56 | 0.29
  10 |                   ->  Streaming(type: BROADCAST) |      3 | 2MB      |      56 | 0.29
  11 |                      ->  CTE Scan on t(1) b      |      1 | 1MB      |      56 | 0.02
  12 |             ->  Nested Loop (13,14)              |      3 | 1MB      |      96 | 0.33
  13 |                ->  CTE Scan on t(1) a            |      1 | 1MB      |      56 | 0.02
  14 |                ->  Materialize                   |      3 | 16MB     |      56 | 0.29
  15 |                   ->  Streaming(type: BROADCAST) |      3 | 2MB      |      56 | 0.29
  16 |                      ->  CTE Scan on t(1) b      |      1 | 1MB      |      56 | 0.02
  17 |             ->  Nested Loop (18,19)              |      3 | 1MB      |      96 | 0.33
  18 |                ->  CTE Scan on t(1) a            |      1 | 1MB      |      56 | 0.02
  19 |                ->  Materialize                   |      3 | 16MB     |      56 | 0.29
  20 |                   ->  Streaming(type: BROADCAST) |      3 | 2MB      |      56 | 0.29
  21 |                      ->  CTE Scan on t(1) b      |      1 | 1MB      |      56 | 0.02

                         Predicate Information (identified by plan id)
 ----------------------------------------------------------------------------------------------
   7 --Nested Loop (8,9)
         Join Filter: ((a.rzsj >= b.rzsj) AND (a.rzsj <= b.ldsj) AND (a.rzmod = b.rzmod))
  12 --Nested Loop (13,14)
         Join Filter: ((a.rzsj >= b.rzsj) AND (a.rzsj <= b.ldsj) AND (a.rzmod = (b.rzmod + 1)))
  17 --Nested Loop (18,19)
         Join Filter: ((a.rzsj >= b.rzsj) AND (a.rzsj <= b.ldsj) AND (a.rzmod = (b.rzmod - 1)))
【版权声明】本文为华为云社区用户原创内容,转载时必须标注文章的来源(华为云社区)、文章链接、文章作者等基本信息, 否则作者和本社区有权追究责任。如果您发现本社区中有涉嫌抄袭的内容,欢迎发送邮件进行举报,并提供相关证据,一经查实,本社区将立刻删除涉嫌侵权内容,举报邮箱: cloudbbs@huaweicloud.com
  • 点赞
  • 收藏
  • 关注作者

评论(0

0/1000
抱歉,系统识别当前为高风险访问,暂不支持该操作

全部回复

上滑加载中

设置昵称

在此一键设置昵称,即可参与社区互动!

*长度不超过10个汉字或20个英文字符,设置后3个月内不可修改。

*长度不超过10个汉字或20个英文字符,设置后3个月内不可修改。