前往小程序,Get更优阅读体验!
立即前往
首页
学习
活动
专区
工具
TVP
发布
社区首页 >专栏 >with as 语句真的会把查询的数据存内存嘛?

with as 语句真的会把查询的数据存内存嘛?

作者头像
数据仓库践行者
发布2021-04-09 10:24:04
2.2K0
发布2021-04-09 10:24:04
举报

面对网上的一些结论,我们要有自己的判断。从源码中找真相~~

最近有好几个朋友都有咨询这个问题,大概有两类:

1、为啥我用了with..as效率没有提高?

2、sql跑不动,改成with..as的写法,会不会更好些?

网上博客几乎都有结论with ... as语句会把数据放在内存:

hive-sql

在hive中有一个参数

代码语言:javascript
复制
hive.optimize.cte.materialize.threshold

这个参数在默认情况下是-1(关闭的);当开启(大于0),比如设置为2,则如果with..as语句被引用2次及以上时,会把with..as语句生成的table物化,从而做到with..as语句只执行一次,来提高效率。

测试

代码语言:javascript
复制
explain
with atable as (
     SELECT  id,source,channel
            FROM  test

)
select source from atable WHERE   channel = '直播'
union ALL
select source from atable WHERE   channel = '视频'

不设置该参数时,执行计划:

代码语言:javascript
复制
STAGE DEPENDENCIES:
 Stage-1 is a root stage
 Stage-0 depends on stages: Stage-1

STAGE PLANS:
 Stage: Stage-1
  Map Reduce
   Map Operator Tree:
     TableScan
      alias: test
      Statistics: Num rows: 1 Data size: 0 Basic stats: PARTIAL Column stats: NONE
      Filter Operator
       predicate: (channel = '直播') (type: boolean)
       Statistics: Num rows: 1 Data size: 0 Basic stats: PARTIAL Column stats: NONE
       Select Operator
        expressions: source (type: string)
        outputColumnNames: _col0
        Statistics: Num rows: 1 Data size: 0 Basic stats: PARTIAL Column stats: NONE
        Union
         Statistics: Num rows: 2 Data size: 0 Basic stats: PARTIAL Column stats: NONE
         File Output Operator
          compressed: false
          Statistics: Num rows: 2 Data size: 0 Basic stats: PARTIAL Column stats: NONE
          table:
            input format: org.apache.hadoop.mapred.SequenceFileInputFormat
            output format: org.apache.hadoop.hive.ql.io.HiveSequenceFileOutputFormat
            serde: org.apache.hadoop.hive.serde2.lazy.LazySimpleSerDe
     TableScan
      alias: test
      Statistics: Num rows: 1 Data size: 0 Basic stats: PARTIAL Column stats: NONE
      Filter Operator
       predicate: (channel = '视频') (type: boolean)
       Statistics: Num rows: 1 Data size: 0 Basic stats: PARTIAL Column stats: NONE
       Select Operator
        expressions: source (type: string)
        outputColumnNames: _col0
        Statistics: Num rows: 1 Data size: 0 Basic stats: PARTIAL Column stats: NONE
        Union
         Statistics: Num rows: 2 Data size: 0 Basic stats: PARTIAL Column stats: NONE
         File Output Operator
          compressed: false
          Statistics: Num rows: 2 Data size: 0 Basic stats: PARTIAL Column stats: NONE
          table:
            input format: org.apache.hadoop.mapred.SequenceFileInputFormat
            output format: org.apache.hadoop.hive.ql.io.HiveSequenceFileOutputFormat
            serde: org.apache.hadoop.hive.serde2.lazy.LazySimpleSerDe

 Stage: Stage-0
  Fetch Operator
   limit: -1
   Processor Tree:
    ListSink

从执行计划上看,test表被读两次。

设置set hive.optimize.cte.materialize.threshold=1

,执行计划:

代码语言:javascript
复制
STAGE DEPENDENCIES:
 Stage-1 is a root stage
 Stage-6 depends on stages: Stage-1 , consists of Stage-3, Stage-2, Stage-4
 Stage-3
 Stage-0 depends on stages: Stage-3, Stage-2, Stage-5
 Stage-8 depends on stages: Stage-0
 Stage-2
 Stage-4
 Stage-5 depends on stages: Stage-4
 Stage-7 depends on stages: Stage-8

STAGE PLANS:
 Stage: Stage-1
  Map Reduce
   Map Operator Tree:
     TableScan
      alias: test
      Statistics: Num rows: 1 Data size: 0 Basic stats: PARTIAL Column stats: NONE
      Select Operator
       expressions: id (type: int), source (type: string), channel (type: string)
       outputColumnNames: _col0, _col1, _col2
       Statistics: Num rows: 1 Data size: 0 Basic stats: PARTIAL Column stats: NONE
       File Output Operator
        compressed: false
        Statistics: Num rows: 1 Data size: 0 Basic stats: PARTIAL Column stats: NONE
        table:
          input format: org.apache.hadoop.mapred.TextInputFormat
          output format: org.apache.hadoop.hive.ql.io.HiveIgnoreKeyTextOutputFormat
          serde: org.apache.hadoop.hive.serde2.lazy.LazySimpleSerDe
          name: default.atable

 Stage: Stage-6
  Conditional Operator

 Stage: Stage-3
  Move Operator
   files:
     hdfs directory: true
     destination: hdfs://localhost:9000/tmp/hive/bytedance/bae441cb-0ef6-4e9c-9f7a-8a5f97d0e560/_tmp_space.db/ce44793b-6eed-4299-b737-f05c66b2281b/.hive-staging_hive_2021-03-24_20-17-38_169_5695913330535939856-1/-ext-10002

 Stage: Stage-0
  Move Operator
   files:
     hdfs directory: true
     destination: hdfs://localhost:9000/tmp/hive/bytedance/bae441cb-0ef6-4e9c-9f7a-8a5f97d0e560/_tmp_space.db/ce44793b-6eed-4299-b737-f05c66b2281b

 Stage: Stage-8
  Map Reduce
   Map Operator Tree:
     TableScan
      alias: atable
      Statistics: Num rows: 1 Data size: 0 Basic stats: PARTIAL Column stats: NONE
      Filter Operator
       predicate: (channel = '直播') (type: boolean)
       Statistics: Num rows: 1 Data size: 0 Basic stats: PARTIAL Column stats: NONE
       Select Operator
        expressions: source (type: string)
        outputColumnNames: _col0
        Statistics: Num rows: 1 Data size: 0 Basic stats: PARTIAL Column stats: NONE
        Union
         Statistics: Num rows: 2 Data size: 0 Basic stats: PARTIAL Column stats: NONE
         File Output Operator
          compressed: false
          Statistics: Num rows: 2 Data size: 0 Basic stats: PARTIAL Column stats: NONE
          table:
            input format: org.apache.hadoop.mapred.SequenceFileInputFormat
            output format: org.apache.hadoop.hive.ql.io.HiveSequenceFileOutputFormat
            serde: org.apache.hadoop.hive.serde2.lazy.LazySimpleSerDe
     TableScan
      alias: atable
      Statistics: Num rows: 1 Data size: 0 Basic stats: PARTIAL Column stats: NONE
      Filter Operator
       predicate: (channel = '视频') (type: boolean)
       Statistics: Num rows: 1 Data size: 0 Basic stats: PARTIAL Column stats: NONE
       Select Operator
        expressions: source (type: string)
        outputColumnNames: _col0
        Statistics: Num rows: 1 Data size: 0 Basic stats: PARTIAL Column stats: NONE
        Union
         Statistics: Num rows: 2 Data size: 0 Basic stats: PARTIAL Column stats: NONE
         File Output Operator
          compressed: false
          Statistics: Num rows: 2 Data size: 0 Basic stats: PARTIAL Column stats: NONE
          table:
            input format: org.apache.hadoop.mapred.SequenceFileInputFormat
            output format: org.apache.hadoop.hive.ql.io.HiveSequenceFileOutputFormat
            serde: org.apache.hadoop.hive.serde2.lazy.LazySimpleSerDe

 Stage: Stage-2
  Map Reduce
   Map Operator Tree:
     TableScan
      File Output Operator
       compressed: false
       table:
         input format: org.apache.hadoop.mapred.TextInputFormat
         output format: org.apache.hadoop.hive.ql.io.HiveIgnoreKeyTextOutputFormat
         serde: org.apache.hadoop.hive.serde2.lazy.LazySimpleSerDe
         name: default.atable

 Stage: Stage-4
  Map Reduce
   Map Operator Tree:
     TableScan
      File Output Operator
       compressed: false
       table:
         input format: org.apache.hadoop.mapred.TextInputFormat
         output format: org.apache.hadoop.hive.ql.io.HiveIgnoreKeyTextOutputFormat
         serde: org.apache.hadoop.hive.serde2.lazy.LazySimpleSerDe
         name: default.atable

 Stage: Stage-5
  Move Operator
   files:
     hdfs directory: true
     destination: hdfs://localhost:9000/tmp/hive/bytedance/bae441cb-0ef6-4e9c-9f7a-8a5f97d0e560/_tmp_space.db/ce44793b-6eed-4299-b737-f05c66b2281b/.hive-staging_hive_2021-03-24_20-17-38_169_5695913330535939856-1/-ext-10002

 Stage: Stage-7
  Fetch Operator
   limit: -1
   Processor Tree:
    ListSink

可以看到test表被物化了。

源码:

从源码看,在获取元数据时,会做参数判断,判断参数阈值及cte的引用次数

spark-sql

spark对cte的操作比较少,在spark侧,现在还没发现有相关的优化参数

代码语言:javascript
复制
with atable as (
     SELECT  content_type,
                    channel,
                    channel_note,
                    enter_method,
                    enter_method_note
            FROM    search_dw.dim_ecom_enter_channel_df
            
)
select channel from atable WHERE   content_type = '直播'
union ALL
select channel from atable WHERE   content_type = '视频'
本文参与 腾讯云自媒体分享计划,分享自微信公众号。
原始发表:2021-03-31,如有侵权请联系 cloudcommunity@tencent.com 删除

本文分享自 数据仓库践行者 微信公众号,前往查看

如有侵权,请联系 cloudcommunity@tencent.com 删除。

本文参与 腾讯云自媒体分享计划  ,欢迎热爱写作的你一起参与!

评论
登录后参与评论
0 条评论
热度
最新
推荐阅读
相关产品与服务
云直播
云直播(Cloud Streaming Services,CSS)为您提供极速、稳定、专业的云端直播处理服务,根据业务的不同直播场景需求,云直播提供了标准直播、快直播、云导播台三种服务,分别针对大规模实时观看、超低延时直播、便捷云端导播的场景,配合腾讯云视立方·直播 SDK,为您提供一站式的音视频直播解决方案。
领券
问题归档专栏文章快讯文章归档关键词归档开发者手册归档开发者手册 Section 归档