sql中列转行unpivot、行转列pivot详细讲解||Mys

作者: 夜希辰 | 来源:发表于2020-05-10 19:59 被阅读0次

    目录:
    一、sqlserver列转行、行转列详解
    二、Oracle列转行、行转列详解
    三、DB2列转行、行转列详解
    四、MYSQL列转行、行专列详解
    五、练习数据

    练习数据在文末,使用时需要修改表名,和建表语句

    每次学习新语法时,我习惯性的在四种数据库中逐一练习,这个是职业习惯哈哈。虽然去年写过oracle,db2列转行文章,不过……感觉除了我没人可以看懂,附上去年文章的截图,不过说实话DB2列转行使用跟其他数据库差距还是挺大。

    灵机一动,发现还可以附带可以把with函数学习了。上面都是个人感悟,现在我们一起学习Mysql Oracle sqlserv DB2列转行、行转列的使用吧。
    上班的时候公司开发很惊讶说“你居然会用列转行”

    一、sqlserver列转行、行转列详解

    我们看下这张表,总共是26列,1547行数据

    select  *  from water_quality
    

    1、列转行unpivot

    UNPIVOT函数的格式如下:

    UNPIVOT([转换为行的列值在转换后对应的列名] for [转换为行的列名在转换后对应的列名] 
    in ([转换为行的列1],[转换为行的列2],[转换为行的列3],...[转换为行的列N]))
    

    函数讲解:

    • [转换为行的列值在转换后对应的列名]这个是进行列转行的列其数据值在转换为行后的列名称,就是要转换的列对应的数据值用什么字段表示
    • [转换为行的列名在转换后对应的列名]这个是进行列转行的列其列名在转换为行后的列名称,就是要转换的列用什么字段表示
    • [转换为行的列]这个是声明哪些列要进行列转行,就是要转换为行的列名逐一列出来

    问题1:把PJJG后的字段转换为行

    
    select 
    //NF, YF, HL, DMMC, PJJG ----这里不能单独列几个字段,一定要用select *,至于结果差异大家可以运行后体会
    * from water_quality
    unpivot(  
    //   POLLUTEVALUE for CODE_POLLUTE---上面字段无中括号就报错,按照下面有中括号的格式就不报错。不知道是不是数据库不兼容
     [POLLUTEVALUE] for [CODE_POLLUTE]
     IN(
    JCXM_PH ,   JCXM_RYL,JCXM_GMSYZS ,JCXM_SHXYL ,JCXM_AD ,JCXM_SYL,JCXM_HFF,JCXM_GONG  ,JCXM_QIAN  ,JCXM_GE ,JCXM_YLZBMHXJ  ,JCXM_LUO,JCXM_FHW,JCXM_ZL ,JCXM_QHW,JCXM_LHW,JCXM_SHEN  ,JCXM_HXXYL ,
    JCXM_TONG  ,JCXM_XIN,JCXM_XI ))
    as a--------#as一定要有,没有就报错,我也不知道为什么。可能是特定的语法格式吧
    
    [转换为行的**列值**在转换后对应的列名]对应POLLUTEVALUE
    [转换为行的**列名**在转换后对应的列名]对应CODE_POLLUTE
    [转换为行的列]对应JCXM_PH , JCXM_RYL,JCXM_GMSYZS ,JCXM_SHXYL ,JCXM_AD ,JCXM_SYL,JCXM_HFF,JCXM_GONG  ,JCXM_QIAN  ,JCXM_GE ,JCXM_YLZBMHXJ  ,JCXM_LUO,JCXM_FHW,JCXM_ZL,JCXM_QHW,JCXM_LHW,JCXM_SHEN  ,JCXM_HXXYL ,JCXM_TONG  ,JCXM_XIN,JCXM_XI
    

    我们看下转换后的结果

    2、行转列PIVOT

    PIVOT函数的格式如下

    PIVOT(<聚合函数>([聚合列值]) FOR [行转列前的列名]
     IN([行转列后的列名1],[行转列后的列名2],[行转列后的列名3],.......[行转列后的列名N]))
    

    函数讲解:

    • <聚合函数>就是我们使用的SUM,COUNT,AVG等Sql聚合函数,也就是行转列后计算列的聚合方式。
    • [聚合列值]要进行聚合的列名
    • [行转列前的列名]这个就是需要将行转换为列的列名
    • [行转列后的列名]这里需要声明将行的值转换为列后的列名,因为转换后的列名其实就是转换前行的值,所以上面格式中的[行转列后的列名1],[行转列后的列名2],[行转列后的列名3],......[行转列后的列名N]其实就是[行转列前的列名]每一行的值。

    问题2:把CODE_POLLUTE污染物编码字段以列的方式显示

    解答1:
     ---water_quality_temp这个表是问题1查询后保存的结果表啦
    select *
    from water_quality_temp 
    PIVOT(max(POLLUTEVALUE) FOR [CODE_POLLUTE] -----#max换成count会看见不同的结果
    IN(JCXM_PH ,    JCXM_RYL,JCXM_GMSYZS ,JCXM_SHXYL ,JCXM_AD ,JCXM_SYL,JCXM_HFF,JCXM_GONG  ,JCXM_QIAN  ,JCXM_GE ,JCXM_YLZBMHXJ  ,JCXM_LUO,JCXM_FHW,JCXM_ZL ,JCXM_QHW,JCXM_LHW,JCXM_SHEN  ,JCXM_HXXYL ,
    JCXM_TONG  ,JCXM_XIN,JCXM_XI)) AS T 
    
    解答2:
    -----如果没有将问题1结果报错,可以这样写
    with water_quality_temp as(
    select 
    //NF, YF, HL, DMMC, PJJG ----这里不能单独列几个字段,一定要用select *,至于结果差异大家可以运行后体会
    * from water_quality
    unpivot(  
    //   POLLUTEVALUE for CODE_POLLUTE---上面字段无中括号就包括,按照下面有中括号的格式就不报错。不知道是不是不兼容
     [POLLUTEVALUE] for [CODE_POLLUTE]
     IN(JCXM_PH ,   JCXM_RYL,JCXM_GMSYZS ,JCXM_SHXYL ,JCXM_AD ,JCXM_SYL,JCXM_HFF,JCXM_GONG  ,JCXM_QIAN  ,JCXM_GE ,JCXM_YLZBMHXJ  ,JCXM_LUO,JCXM_FHW,JCXM_ZL ,JCXM_QHW,JCXM_LHW,JCXM_SHEN  ,JCXM_HXXYL ,
    JCXM_TONG  ,JCXM_XIN,JCXM_XI ))
    as a)----#as一定要有,没有就报错
    select *
    from water_quality_temp 
    PIVOT(max(POLLUTEVALUE) FOR [CODE_POLLUTE] IN(JCXM_PH , JCXM_RYL,JCXM_GMSYZS ,JCXM_SHXYL ,JCXM_AD ,JCXM_SYL,JCXM_HFF,JCXM_GONG  ,JCXM_QIAN  ,JCXM_GE ,JCXM_YLZBMHXJ  ,JCXM_LUO,JCXM_FHW,JCXM_ZL ,JCXM_QHW,JCXM_LHW,JCXM_SHEN  ,JCXM_HXXYL ,
    JCXM_TONG  ,JCXM_XIN,JCXM_XI)) AS T 
    
    
    - <聚合函数>本例中的max
    - [聚合列值]本例中的POLLUTEVALUE
    - [行转**列前**的列名]本例中的CODE_POLLUTE
    - [行转**列后**的列名]本例中的CXM_PH , JCXM_RYL,JCXM_GMSYZS ,JCXM_SHXYL ,JCXM_AD ,JCXM_SYL,JCXM_HFF,JCXM_GONG  ,JCXM_QIAN  ,JCXM_GE ,JCXM_YLZBMHXJ  ,JCXM_LUO,JCXM_FHW,JCXM_ZL ,JCXM_QHW,JCXM_LHW,JCXM_SHEN  ,JCXM_HXXYL ,JCXM_TONG  ,JCXM_XIN,JCXM_XI
    

    我们看下转换后的结果

    二、Oracle列转行、行转列详解

    1、Oracle列转行unpivot

    UNPIVOT函数的格式如下:

    UNPIVOT([转换为行的列名在转换后对应的列名] for [转换为行的列值在转换后对应的列名] 
    in ([转换为行的列1],[转换为行的列2],[转换为行的列3],...[转换为行的列N]))
    

    函数的讲解
    Oracle列转行函数的讲解跟sqlserver一样,这里就不详细介绍了,我们直接使用
    我们先看下源表

    select  *  from TJSXM.water_quality
    

    问题1:把PJJG后的字段转换为行
    select 
    *  from TJSXM.water_quality
    unpivot(  POLLUTEVALUE for CODE_POLLUTE
     IN(JCXM_PH ,   JCXM_RYL,JCXM_GMSYZS ,JCXM_SHXYL ,JCXM_AD ,JCXM_SYL,JCXM_HFF,JCXM_GONG  ,JCXM_QIAN  ,JCXM_GE ,JCXM_YLZBMHXJ  ,JCXM_LUO,JCXM_FHW,JCXM_ZL ,JCXM_QHW,JCXM_LHW,JCXM_SHEN  ,JCXM_HXXYL ,
    JCXM_TONG  ,JCXM_XIN,JCXM_XI )) 
    ----和SQLSERVER区别,这里没有as
    
    [转换为行的**列值**在转换后对应的列名]对应POLLUTEVALUE
    [转换为行的**列名**在转换后对应的列名]对应CODE_POLLUTE
    [转换为行的列]对应JCXM_PH , JCXM_RYL,JCXM_GMSYZS ,JCXM_SHXYL ,JCXM_AD ,JCXM_SYL,JCXM_HFF,JCXM_GONG  ,JCXM_QIAN  ,JCXM_GE ,JCXM_YLZBMHXJ  ,JCXM_LUO,JCXM_FHW,JCXM_ZL,JCXM_QHW,JCXM_LHW,JCXM_SHEN  ,JCXM_HXXYL ,JCXM_TONG  ,JCXM_XIN,JCXM_XI
    

    我们看下结果

    2、Oracle行转列pivot

    PIVOT函数的格式如下

    PIVOT(<聚合函数>([聚合列值]) FOR [行转列前的列名]
     IN('行转列前的列名值1' [行转列后的列名1],' 行转列前的列名值2'  [行转列后的列名2],'行转列前的列名值3' [行转列后的列名3],.......' 行转列前的列名值n'  [行转列后的列名N]))
    
    #行转列前的列名值2=
    #select  distinct  行转列前的列名 from 表名
    

    问题2:把POLLUTEVALUE污染物编码字段以列的方式显示

    select *
    from TJSXM.water_quality_temp 
    PIVOT(max(CODE_POLLUTE) FOR POLLUTEVALUE IN(---- --#POLLUTEVALUE 即要转成列的字段
    'JCXM_PH'  JCXM_PH,------#max(CODE_POLLUTE) 此处必须为聚合函数
    'JCXM_RYL'  JCXM_RYL,-----------#in () 对要转成列的每一个值指定一个列名
    'JCXM_GMSYZS'  JCXM_GMSYZS,
    'JCXM_SHXYL'  JCXM_SHXYL,
    'JCXM_AD'  JCXM_AD,
    'JCXM_SYL'  JCXM_SYL,
    'JCXM_HFF'  JCXM_HFF,
    'JCXM_GONG'  JCXM_GONG,
    'JCXM_QIAN'  JCXM_QIAN,
    'JCXM_GE'  JCXM_GE,
    'JCXM_YLZBMHXJ'  JCXM_YLZBMHXJ,
    'JCXM_LUO'  JCXM_LUO,
    'JCXM_FHW'  JCXM_FHW,
    'JCXM_ZL'  JCXM_ZL,
    'JCXM_QHW'  JCXM_QHW,
    'JCXM_LHW'  JCXM_LHW,
    'JCXM_SHEN'  JCXM_SHEN,
    'JCXM_HXXYL'  JCXM_HXXYL,
    'JCXM_TONG'  JCXM_TONG,
    'JCXM_XIN'  JCXM_XIN,
    'JCXM_XI'  JCXM_XI))
    

    我们看下结果

    image.png

    三、DB2列转行、行转列详解

    1、DB2列转行

    先看下源表

    select * from TJSXM.water_quality_temp
    

    函数格式:
    DB2列转行不能使用函数unpivot,也没找到相应的函数格式,带大家从案例里面体会

    问题1:把PJJG后的字段转换为行

    select 
    a.NF,a.YF,a.HL,a.DMMC,a.DMLX ,a.PJJG,q.polutcode,q.polut_value
    from TJSXM.water_quality a,
    TABLE (VALUES
    ('Ph(pH无量纲)',a.JCXM_PH),
    ('溶解氧',a.JCXM_RYL),
    ('高锰酸盐指数',a.JCXM_GMSYZS),
    ('生化需氧量(BOD5)',a.JCXM_SHXYL),
    ('氨氮',a.JCXM_AD),
    ('石油类(石油醚萃取)',a.JCXM_SYL),
    ('挥发酚',a.JCXM_HFF),
    ('汞',a.JCXM_GONG),
    ('铅',a.JCXM_QIAN),
    ('镉',a.JCXM_GE),
    ('阴离子表面活性剂',a.JCXM_YLZBMHXJ),
    ('铬(六价)',a.JCXM_LUO),
    ('氟化物(以F-计)',a.JCXM_FHW),
    ('总磷(以P计)',a.JCXM_ZL),
    ('氰化物',a.JCXM_QHW),
    ('硫化物',a.JCXM_LHW),
    ('砷',a.JCXM_SHEN),
    ('化学需氧量(CODcr)',a.JCXM_HXXYL),
    ('铜',a.JCXM_TONG),
    ('锌',a.JCXM_XIN),
    ('硒(四价)',a.JCXM_XI)
    )
    AS q(polutcode, polut_value)
    #每个values中对应列的数据类型必须相同,值可以任意,如1,2,3,4都是整形
    

    下面解释一下执行的过程:
    核心是用table函数创建了一个表,这个表是用value实现的多行表,value实现虚表的例子:

    所不同的是这里跟from子句中的一个表产生了关系,取出了表中的一列作为数据。参考文章:db2中的列转行和行转列

    我们看下列转行结果:

    2、DB2行转列

    函数格式
    很遗憾DB2行转列不能使用unpivot函数,只能用max函数。我们一起写下吧

    问题2:把CODE_POLLUTE 污染物编码字段以列的方式显示

    select
      NF,YF,HL,DMMC,PJJG,
     max(case when  CODE_POLLUTE = 'JCXM_PH'then POLLUTEVALUE end) JCXM_PHJCXM_PH ,
    max(case when  CODE_POLLUTE = 'JCXM_RYL'then POLLUTEVALUE end) JCXM_RYLJCXM_PH ,
    max(case when  CODE_POLLUTE = 'JCXM_GMSYZS'then POLLUTEVALUE end) JCXM_GMSYZSJCXM_PH ,
    max(case when  CODE_POLLUTE = 'JCXM_SHXYL'then POLLUTEVALUE end) JCXM_SHXYLJCXM_PH ,
    max(case when  CODE_POLLUTE = 'JCXM_AD'then POLLUTEVALUE end) JCXM_ADJCXM_PH ,
    max(case when  CODE_POLLUTE = 'JCXM_SYL'then POLLUTEVALUE end) JCXM_SYLJCXM_PH ,
    max(case when  CODE_POLLUTE = 'JCXM_HFF'then POLLUTEVALUE end) JCXM_HFFJCXM_PH ,
    max(case when  CODE_POLLUTE = 'JCXM_GONG'then POLLUTEVALUE end) JCXM_GONGJCXM_PH ,
    max(case when  CODE_POLLUTE = 'JCXM_QIAN'then POLLUTEVALUE end) JCXM_QIANJCXM_PH ,
    max(case when  CODE_POLLUTE = 'JCXM_GE'then POLLUTEVALUE end) JCXM_GEJCXM_PH ,
    max(case when  CODE_POLLUTE = 'JCXM_YLZBMHXJ'then POLLUTEVALUE end) JCXM_YLZBMHXJJCXM_PH ,
    max(case when  CODE_POLLUTE = 'JCXM_LUO'then POLLUTEVALUE end) JCXM_LUOJCXM_PH ,
    max(case when  CODE_POLLUTE = 'JCXM_FHW'then POLLUTEVALUE end) JCXM_FHWJCXM_PH ,
    max(case when  CODE_POLLUTE = 'JCXM_ZL'then POLLUTEVALUE end) JCXM_ZLJCXM_PH ,
    max(case when  CODE_POLLUTE = 'JCXM_QHW'then POLLUTEVALUE end) JCXM_QHWJCXM_PH ,
    max(case when  CODE_POLLUTE = 'JCXM_LHW'then POLLUTEVALUE end) JCXM_LHWJCXM_PH ,
    max(case when  CODE_POLLUTE = 'JCXM_SHEN'then POLLUTEVALUE end) JCXM_SHENJCXM_PH ,
    max(case when  CODE_POLLUTE = 'JCXM_HXXYL'then POLLUTEVALUE end) JCXM_HXXYLJCXM_PH ,
    max(case when  CODE_POLLUTE = 'JCXM_TONG'then POLLUTEVALUE end) JCXM_TONGJCXM_PH ,
    max(case when  CODE_POLLUTE = 'JCXM_XIN'then POLLUTEVALUE end) JCXM_XINJCXM_PH ,
    max(case when  CODE_POLLUTE = 'JCXM_XI'then POLLUTEVALUE end) JCXM_XIJCXM_PH 
     from  water_quality_temp ----已存在数据库中
     group by NF,YF,HL,DMMC,PJJG
    

    我们看下运行结果:

    四、MYSQL列转行、行转列详解

    1、MYSQL列转行

    函数格式
    MYSQL列转行是不能使用unpivot函数的,我在网上百度了3个小时都没找到。所以先用union all函数吧【内心很崩溃】

    问题1:把PJJG后的字段转换为一行

    select NF,YF,HL,DMMC,PJJG, 'JCXM_PH' CODE_POLLUTE , JCXM_PH as POLLUTEVALUE from water_quality
    union select NF,YF,HL,DMMC,PJJG, 'JCXM_PH' CODE_POLLUTE, JCXM_PH as POLLUTEVALUE from water_quality
    union select NF,YF,HL,DMMC,PJJG, 'JCXM_RYL' CODE_POLLUTE, JCXM_RYL as POLLUTEVALUE from water_quality
    union select NF,YF,HL,DMMC,PJJG, 'JCXM_GMSYZS' CODE_POLLUTE, JCXM_GMSYZS as POLLUTEVALUE from water_quality
    union select NF,YF,HL,DMMC,PJJG, 'JCXM_SHXYL' CODE_POLLUTE, JCXM_SHXYL as POLLUTEVALUE from water_quality
    union select NF,YF,HL,DMMC,PJJG, 'JCXM_AD' CODE_POLLUTE, JCXM_AD as POLLUTEVALUE from water_quality
    union select NF,YF,HL,DMMC,PJJG, 'JCXM_SYL' CODE_POLLUTE, JCXM_SYL as POLLUTEVALUE from water_quality
    union select NF,YF,HL,DMMC,PJJG, 'JCXM_HFF' CODE_POLLUTE, JCXM_HFF as POLLUTEVALUE from water_quality
    union select NF,YF,HL,DMMC,PJJG, 'JCXM_GONG' CODE_POLLUTE, JCXM_GONG as POLLUTEVALUE from water_quality
    union select NF,YF,HL,DMMC,PJJG, 'JCXM_QIAN' CODE_POLLUTE, JCXM_QIAN as POLLUTEVALUE from water_quality
    union select NF,YF,HL,DMMC,PJJG, 'JCXM_GE' CODE_POLLUTE, JCXM_GE as POLLUTEVALUE from water_quality
    union select NF,YF,HL,DMMC,PJJG, 'JCXM_YLZBMHXJ' CODE_POLLUTE, JCXM_YLZBMHXJ as POLLUTEVALUE from water_quality
    union select NF,YF,HL,DMMC,PJJG, 'JCXM_LUO' CODE_POLLUTE, JCXM_LUO as POLLUTEVALUE from water_quality
    union select NF,YF,HL,DMMC,PJJG, 'JCXM_FHW' CODE_POLLUTE, JCXM_FHW as POLLUTEVALUE from water_quality
    union select NF,YF,HL,DMMC,PJJG, 'JCXM_ZL' CODE_POLLUTE, JCXM_ZL as POLLUTEVALUE from water_quality
    union select NF,YF,HL,DMMC,PJJG, 'JCXM_QHW' CODE_POLLUTE, JCXM_QHW as POLLUTEVALUE from water_quality
    union select NF,YF,HL,DMMC,PJJG, 'JCXM_LHW' CODE_POLLUTE, JCXM_LHW as POLLUTEVALUE from water_quality
    union select NF,YF,HL,DMMC,PJJG, 'JCXM_SHEN' CODE_POLLUTE, JCXM_SHEN as POLLUTEVALUE from water_quality
    union select NF,YF,HL,DMMC,PJJG, 'JCXM_HXXYL' CODE_POLLUTE, JCXM_HXXYL as POLLUTEVALUE from water_quality
    union select NF,YF,HL,DMMC,PJJG, 'JCXM_TONG' CODE_POLLUTE, JCXM_TONG as POLLUTEVALUE from water_quality
    union select NF,YF,HL,DMMC,PJJG, 'JCXM_XIN' CODE_POLLUTE, JCXM_XIN as POLLUTEVALUE from water_quality
    union select NF,YF,HL,DMMC,PJJG, 'JCXM_XI' CODE_POLLUTE, JCXM_XI as POLLUTEVALUE from water_quality
    order by NF,YF,HL,DMMC,PJJG
    

    我们看下运行结果

    2、MYSQL行转列

    函数格式
    很遗憾MYSQL行转列不能使用unpivot函数,只能跟DB2数据库一样,只能用max函数。

    问题2:把CODE_POLLUTE 污染物编码字段以列的方式显示

    select
      NF,YF,HL,DMMC,PJJG,
     max(case when  CODE_POLLUTE = 'JCXM_PH'then POLLUTEVALUE end) JCXM_PHJCXM_PH ,
    max(case when  CODE_POLLUTE = 'JCXM_RYL'then POLLUTEVALUE end) JCXM_RYLJCXM_PH ,
    max(case when  CODE_POLLUTE = 'JCXM_GMSYZS'then POLLUTEVALUE end) JCXM_GMSYZSJCXM_PH ,
    max(case when  CODE_POLLUTE = 'JCXM_SHXYL'then POLLUTEVALUE end) JCXM_SHXYLJCXM_PH ,
    max(case when  CODE_POLLUTE = 'JCXM_AD'then POLLUTEVALUE end) JCXM_ADJCXM_PH ,
    max(case when  CODE_POLLUTE = 'JCXM_SYL'then POLLUTEVALUE end) JCXM_SYLJCXM_PH ,
    max(case when  CODE_POLLUTE = 'JCXM_HFF'then POLLUTEVALUE end) JCXM_HFFJCXM_PH ,
    max(case when  CODE_POLLUTE = 'JCXM_GONG'then POLLUTEVALUE end) JCXM_GONGJCXM_PH ,
    max(case when  CODE_POLLUTE = 'JCXM_QIAN'then POLLUTEVALUE end) JCXM_QIANJCXM_PH ,
    max(case when  CODE_POLLUTE = 'JCXM_GE'then POLLUTEVALUE end) JCXM_GEJCXM_PH ,
    max(case when  CODE_POLLUTE = 'JCXM_YLZBMHXJ'then POLLUTEVALUE end) JCXM_YLZBMHXJJCXM_PH ,
    max(case when  CODE_POLLUTE = 'JCXM_LUO'then POLLUTEVALUE end) JCXM_LUOJCXM_PH ,
    max(case when  CODE_POLLUTE = 'JCXM_FHW'then POLLUTEVALUE end) JCXM_FHWJCXM_PH ,
    max(case when  CODE_POLLUTE = 'JCXM_ZL'then POLLUTEVALUE end) JCXM_ZLJCXM_PH ,
    max(case when  CODE_POLLUTE = 'JCXM_QHW'then POLLUTEVALUE end) JCXM_QHWJCXM_PH ,
    max(case when  CODE_POLLUTE = 'JCXM_LHW'then POLLUTEVALUE end) JCXM_LHWJCXM_PH ,
    max(case when  CODE_POLLUTE = 'JCXM_SHEN'then POLLUTEVALUE end) JCXM_SHENJCXM_PH ,
    max(case when  CODE_POLLUTE = 'JCXM_HXXYL'then POLLUTEVALUE end) JCXM_HXXYLJCXM_PH ,
    max(case when  CODE_POLLUTE = 'JCXM_TONG'then POLLUTEVALUE end) JCXM_TONGJCXM_PH ,
    max(case when  CODE_POLLUTE = 'JCXM_XIN'then POLLUTEVALUE end) JCXM_XINJCXM_PH ,
    max(case when  CODE_POLLUTE = 'JCXM_XI'then POLLUTEVALUE end) JCXM_XIJCXM_PH 
     from  water_quality_temp ----已存在数据库中
     group by NF,YF,HL,DMMC,PJJG
    

    我们看下运行结果:

    五、练习数据

    使用时需要数据库修改表名,和建表语句
    建表语句

    CREATE TABLE water_quality  ( 
        NF              varchar(20) NULL,
        YF              varchar(20) NULL,
        HL              varchar(50) NULL,
        DMMC            varchar(50) NULL,
        PJJG            varchar(50) NULL,
        JCXM_PH         varchar(50) NULL,
        JCXM_RYL        varchar(50) NULL,
        JCXM_GMSYZS     varchar(50) NULL,
        JCXM_SHXYL      varchar(50) NULL,
        JCXM_AD         varchar(50) NULL,
        JCXM_SYL        varchar(50) NULL,
        JCXM_HFF        varchar(50) NULL,
        JCXM_GONG       varchar(50) NULL,
        JCXM_QIAN       varchar(50) NULL,
        JCXM_GE         varchar(50) NULL,
        JCXM_YLZBMHXJ   varchar(50) NULL,
        JCXM_LUO        varchar(50) NULL,
        JCXM_FHW        varchar(50) NULL,
        JCXM_ZL         varchar(50) NULL,
        JCXM_QHW        varchar(50) NULL,
        JCXM_LHW        varchar(50) NULL,
        JCXM_SHEN       varchar(50) NULL,
        JCXM_HXXYL      varchar(50) NULL,
        JCXM_TONG       varchar(50) NULL,
        JCXM_XIN        varchar(50) NULL,
        JCXM_XI         varchar(50) NULL )
    

    插入数据
    数据量太大这里给大家提供网盘。
    网盘链接:https://pan.baidu.com/s/1nTMvJopi9KJFnWOEEHXmQw
    提取码:msoh

    六、感受

    最大的感受就是MYSQL列转行、行转列太不友好了,都没函数提供。

    本来可以拆分成4篇文章的,合并在一个文章啦,以后有需要在拆分吧~~~
    其实不同数据库列转行、行转列区别挺明显的,当然罗如果不用函数,用方法就没什么区别啦

    相关文章

      网友评论

        本文标题:sql中列转行unpivot、行转列pivot详细讲解||Mys

        本文链接:https://www.haomeiwen.com/subject/qlkjnhtx.html