explode_map

description

表函数,需配合 Lateral View 使用, 可以支持多个 Lateral view, 仅仅支持新优化器。

将 map 列展开成多行。当 map 为NULL或者为空时,explode_map_outer 返回NULL。 explode_mapexplode_map_outer 均会返回 map 内部的NULL元素。

syntax

  1. explode_map(expr)
  2. explode_map_outer(expr)

example

  1. mysql> set enable_vectorized_engine = true
  2. mysql> SET enable_nereids_planner=true
  3. mysql> SET enable_fallback_to_original_planner=false
  4. mysql> CREATE TABLE IF NOT EXISTS `sdu`(
  5. `id` INT NULL,
  6. `name` TEXT NULL,
  7. `score` MAP<TEXT,INT> NULL
  8. ) ENGINE=OLAP
  9. DUPLICATE KEY(`id`)
  10. COMMENT 'OLAP'
  11. DISTRIBUTED BY HASH(`id`) BUCKETS 1
  12. PROPERTIES ("replication_allocation" = "tag.location.default: 1");
  13. Query OK, 0 rows affected (0.15 sec)
  14. mysql> insert into sdu values (0, "zhangsan", {"Chinese":"80","Math":"60","English":"90"}), (1, "lisi", {"null":null}), (2, "wangwu", {"Chinese":"88","Math":"90","English":"96"}), (3, "lisi2", {null:null}), (4, "amory", NULL);
  15. Query OK, 5 rows affected (0.23 sec)
  16. {'label':'label_9b35d9d9d59147f5_bffb974881ed2133', 'status':'VISIBLE', 'txnId':'4005'}
  17. mysql> select * from sdu order by id;
  18. +------+----------+-----------------------------------------+
  19. | id | name | score |
  20. +------+----------+-----------------------------------------+
  21. | 0 | zhangsan | {"Chinese":80, "Math":60, "English":90} |
  22. | 1 | lisi | {"null":null} |
  23. | 2 | wangwu | {"Chinese":88, "Math":90, "English":96} |
  24. | 3 | lisi2 | {null:null} |
  25. | 4 | amory | NULL |
  26. +------+----------+-----------------------------------------+
  27. mysql> select name, k,v from sdu lateral view explode_map(score) tmp as k,v;
  28. +----------+---------+------+
  29. | name | k | v |
  30. +----------+---------+------+
  31. | zhangsan | Chinese | 80 |
  32. | zhangsan | Math | 60 |
  33. | zhangsan | English | 90 |
  34. | lisi | null | NULL |
  35. | wangwu | Chinese | 88 |
  36. | wangwu | Math | 90 |
  37. | wangwu | English | 96 |
  38. | lisi2 | NULL | NULL |
  39. +----------+---------+------+
  40. mysql> select name, k,v from sdu lateral view explode_map_outer(score) tmp as k,v;
  41. +----------+---------+------+
  42. | name | k | v |
  43. +----------+---------+------+
  44. | zhangsan | Chinese | 80 |
  45. | zhangsan | Math | 60 |
  46. | zhangsan | English | 90 |
  47. | lisi | null | NULL |
  48. | wangwu | Chinese | 88 |
  49. | wangwu | Math | 90 |
  50. | wangwu | English | 96 |
  51. | lisi2 | NULL | NULL |
  52. | amory | NULL | NULL |
  53. +----------+---------+------+
  54. mysql> select name, k,v,k1,v1 from sdu lateral view explode_map_outer(score) tmp as k,v lateral view explode_map(score) tmp2 as k1,v1;
  55. +----------+---------+------+---------+------+
  56. | name | k | v | k1 | v1 |
  57. +----------+---------+------+---------+------+
  58. | zhangsan | Chinese | 80 | Chinese | 80 |
  59. | zhangsan | Chinese | 80 | Math | 60 |
  60. | zhangsan | Chinese | 80 | English | 90 |
  61. | zhangsan | Math | 60 | Chinese | 80 |
  62. | zhangsan | Math | 60 | Math | 60 |
  63. | zhangsan | Math | 60 | English | 90 |
  64. | zhangsan | English | 90 | Chinese | 80 |
  65. | zhangsan | English | 90 | Math | 60 |
  66. | zhangsan | English | 90 | English | 90 |
  67. | lisi | null | NULL | null | NULL |
  68. | wangwu | Chinese | 88 | Chinese | 88 |
  69. | wangwu | Chinese | 88 | Math | 90 |
  70. | wangwu | Chinese | 88 | English | 96 |
  71. | wangwu | Math | 90 | Chinese | 88 |
  72. | wangwu | Math | 90 | Math | 90 |
  73. | wangwu | Math | 90 | English | 96 |
  74. | wangwu | English | 96 | Chinese | 88 |
  75. | wangwu | English | 96 | Math | 90 |
  76. | wangwu | English | 96 | English | 96 |
  77. | lisi2 | NULL | NULL | NULL | NULL |
  78. +----------+---------+------+---------+------+

keywords

EXPLODE_MAP,EXPLODE_MAP_OUTER,MAP