Skip to content

Commit

Permalink
explode func
Browse files Browse the repository at this point in the history
  • Loading branch information
yuanyuan8983 authored and zy-kkk committed Jan 23, 2025
1 parent c57f7c3 commit 10770d0
Show file tree
Hide file tree
Showing 98 changed files with 4,593 additions and 4,586 deletions.

This file was deleted.

129 changes: 102 additions & 27 deletions docs/sql-manual/sql-functions/table-functions/explode-bitmap.md
Original file line number Diff line number Diff line change
Expand Up @@ -24,24 +24,49 @@ specific language governing permissions and limitations
under the License.
-->

## explode_bitmap
## Description

### description
The `explode_bitmap` table function accepts a bitmap type data and maps each bit (bit) of the bitmap to a separate row. It is commonly used for processing bitmap data, expanding each element of the bitmap into separate records. It should be used in conjunction with LATERAL VIEW.

Table functions must be used in conjunction with Lateral View.
`explode_bitmap_outer` works similarly to `explode_bitmap`, but its behavior differs when handling NULL or empty values. It allows records with empty or NULL bitmaps to exist, and in the result, it expands an empty or NULL bitmap into NULL rows.

Expand a bitmap type.
## Syntax

#### syntax
```sql
EXPLODE_BITMAP(<bitmap>)
EXPLODE_BITMAP_OUTER(<bitmap>)
```

## Parameters

| Parameter | Description |
| -- | -- |
| `<bitmap>` | bitmap type |

## Return Value

`explode_bitmap(bitmap)`
Returns a row for each bit in the bitmap, with each row containing a single bit value.

### example
## Examples

Original table data:
```sql
CREATE TABLE example1 (
k1 INT
)DUPLICATE KEY(k1)
DISTRIBUTED BY HASH(k1) BUCKETS AUTO
PROPERTIES (
"replication_allocation" = "tag.location.default: 1");
```

```sql
insert into example1 values(1),(2),(3),(4),(5),(6);
```

```sql
select k1 from example1 order by k1;
```
mysql> select k1 from example1 order by k1;

```text
+------+
| k1 |
+------+
Expand All @@ -54,22 +79,16 @@ mysql> select k1 from example1 order by k1;
+------+
```

Lateral View:
```sql
select k1, e1 from example1 lateral view explode_bitmap(bitmap_empty()) tmp1 as e1 order by k1, e1;
Empty set
```

```sql
select k1, e1 from example1 lateral view explode_bitmap(bitmap_from_string("1")) tmp1 as e1 order by k1, e1;
```
mysql> select k1, e1 from example1 lateral view explode_bitmap(bitmap_empty()) tmp1 as e1 order by k1, e1;
+------+------+
| k1 | e1 |
+------+------+
| 1 | NULL |
| 2 | NULL |
| 3 | NULL |
| 4 | NULL |
| 5 | NULL |
| 6 | NULL |
+------+------+

mysql> select k1, e1 from example1 lateral view explode_bitmap(bitmap_from_string("1")) tmp1 as e1 order by k1, e1;
```text
+------+------+
| k1 | e1 |
+------+------+
Expand All @@ -80,8 +99,13 @@ mysql> select k1, e1 from example1 lateral view explode_bitmap(bitmap_from_strin
| 5 | 1 |
| 6 | 1 |
+------+------+
```

```sql
select k1, e1 from example1 lateral view explode_bitmap(bitmap_from_string("1,2")) tmp1 as e1 order by k1, e1;
```

mysql> select k1, e1 from example1 lateral view explode_bitmap(bitmap_from_string("1,2")) tmp1 as e1 order by k1, e1;
```text
+------+------+
| k1 | e1 |
+------+------+
Expand All @@ -98,8 +122,13 @@ mysql> select k1, e1 from example1 lateral view explode_bitmap(bitmap_from_strin
| 6 | 1 |
| 6 | 2 |
+------+------+
```

```sql
select k1, e1 from example1 lateral view explode_bitmap(bitmap_from_string("1,1000")) tmp1 as e1 order by k1, e1;
```

mysql> select k1, e1 from example1 lateral view explode_bitmap(bitmap_from_string("1,1000")) tmp1 as e1 order by k1, e1;
```text
+------+------+
| k1 | e1 |
+------+------+
Expand All @@ -116,10 +145,15 @@ mysql> select k1, e1 from example1 lateral view explode_bitmap(bitmap_from_strin
| 6 | 1 |
| 6 | 1000 |
+------+------+
```

mysql> select k1, e1, e2 from example1
```sql
select k1, e1, e2 from example1
lateral view explode_bitmap(bitmap_from_string("1,1000")) tmp1 as e1
lateral view explode_split("a,b", ",") tmp2 as e2 order by k1, e1, e2;
```

```text
+------+------+------+
| k1 | e1 | e2 |
+------+------+------+
Expand Down Expand Up @@ -150,6 +184,47 @@ lateral view explode_split("a,b", ",") tmp2 as e2 order by k1, e1, e2;
+------+------+------+
```

### keywords
```sql
CREATE TABLE example (
k1 INT,
v1 bitmap
)DUPLICATE KEY(k1)
DISTRIBUTED BY HASH(k1) BUCKETS AUTO
PROPERTIES (
"replication_allocation" = "tag.location.default: 1");
```

```sql
insert into example values(1,to_bitmap('10101')),(2,to_bitmap('0')),(3,to_bitmap(NULL));
```

```sql
SELECT id, k, v
FROM example
LATERAL VIEW explode_json_object(value_json) exploded_table AS k , v;
```

```text
+------+-------+
| k1 | bit |
+------+-------+
| 2 | 0 |
| 1 | 10101 |
+------+-------+
```

```sql
SELECT id, k, v
FROM example
LATERAL VIEW explode_json_object_outer(value_json) exploded_table AS k, v;
```

explode,bitmap,explode_bitmap
```text
+------+-------+
| k1 | bit |
+------+-------+
| 2 | 0 |
| 1 | 10101 |
| 3 | NULL |
+------+-------+
```
Original file line number Diff line number Diff line change
@@ -1,6 +1,6 @@
---
{
"title": "explode_json_array_double",
"title": "EXPLODE_JSON_ARRAY_DOUBLE",
"language": "en"
}
---
Expand All @@ -26,72 +26,89 @@ under the License.

## Description

The table function is used in conjunction with Lateral View and can support multiple Lateral Views. It only supports the new optimizer.
The `explode_json_array_double` table function accepts a JSON array, where each element is of double-precision floating-point type, and expands each floating-point number in the array into multiple rows, with each row containing one floating-point number. It is used in conjunction with LATERAL VIEW.

It expands an array column into multiple rows and adds a column indicating the position, returning a struct type. When the array is NULL or empty, posexplode_outer returns NULL. Both posexplode and posexplode_outer will return NULL elements within the array.
`explode_json_array_double_outer` is similar to `explode_json_array_double`, but the handling of NULL values is different.

If the JSON string itself is NULL, the `OUTER` version will return one row, with the value as NULL. The normal version will completely ignore such records.

If the JSON array is empty, the `OUTER` version will return one row, with the value as NULL. The normal version will return no results.

## Syntax
```sql
posexplode(array)
posexplode_outer(array)
EXPLODE_JSON_ARRAY_DOUBLE(<json>)
EXPLODE_JSON_ARRAY_DOUBLE_OUTER(<json>)
```

## Return Value

| Parameter | Description |
| -- | -- |
| `<json>` | json type |

## Parameters

Expands the JSON array, creating a row for each element, returning a double-precision floating-point column.

## Examples

```sql
CREATE TABLE json_array_example (
id INT,
json_array STRING
)DUPLICATE KEY(id)
DISTRIBUTED BY HASH(id) BUCKETS AUTO
PROPERTIES (
"replication_allocation" = "tag.location.default: 1");
```

### Example
```sql
INSERT INTO json_array_example (id, json_array) VALUES
(1, '[1, 2, 3, 4, 5]'),
(2, '[1.1, 2.2, 3.3, 4.4]'),
(3, '["apple", "banana", "cherry"]'),
(4, '[{"a": 1}, {"b": 2}, {"c": 3}]'),
(5, '[]'),
(6, 'NULL');
```

```sql
SELECT id, e1
FROM json_array_example
LATERAL VIEW EXPLODE_JSON_ARRAY_DOUBLE(json_array) tmp1 AS e1
WHERE id = 2;
```

```text
+------+------+
| id | e1 |
+------+------+
| 2 | 1.1 |
| 2 | 2.2 |
| 2 | 3.3 |
| 2 | 4.4 |
+------+------+
```

```sql
SELECT id, e1
FROM json_array_example
LATERAL VIEW EXPLODE_JSON_ARRAY_DOUBLE(json_array) tmp1 AS e1
WHERE id = 6;
Empty set (0.01 sec)
```

```sql
CREATE TABLE IF NOT EXISTS `table_test`(
`id` INT NULL,
`name` TEXT NULL,
`score` array<string> NULL
) ENGINE=OLAP
DUPLICATE KEY(`id`)
COMMENT 'OLAP'
DISTRIBUTED BY HASH(`id`) BUCKETS 1
PROPERTIES ("replication_allocation" = "tag.location.default: 1");

mysql> insert into table_test values (0, "zhangsan", ["Chinese","Math","English"]),(1, "lisi", ["null"]),(2, "wangwu", ["88a","90b","96c"]),(3, "lisi2", [null]),(4, "amory", NULL);


mysql [test_query_qa]>select * from table_test order by id;
+------+----------+--------------------------------+
| id | name | score |
+------+----------+--------------------------------+
| 0 | zhangsan | ["Chinese", "Math", "English"] |
| 1 | lisi | ["null"] |
| 2 | wangwu | ["88a", "90b", "96c"] |
| 3 | lisi2 | [null] |
| 4 | amory | NULL |
+------+----------+--------------------------------+

mysql [test_query_qa]>select id,name,score, k,v from table_test lateral view posexplode(score) tmp as k,v order by id;
+------+----------+--------------------------------+------+---------+
| id | name | score | k | v |
+------+----------+--------------------------------+------+---------+
| 0 | zhangsan | ["Chinese", "Math", "English"] | 0 | Chinese |
| 0 | zhangsan | ["Chinese", "Math", "English"] | 1 | Math |
| 0 | zhangsan | ["Chinese", "Math", "English"] | 2 | English |
| 1 | lisi | ["null"] | 0 | null |
| 2 | wangwu | ["88a", "90b", "96c"] | 0 | 88a |
| 2 | wangwu | ["88a", "90b", "96c"] | 1 | 90b |
| 2 | wangwu | ["88a", "90b", "96c"] | 2 | 96c |
| 3 | lisi2 | [null] | 0 | NULL |
+------+----------+--------------------------------+------+---------+

mysql [test_query_qa]>select id,name,score, k,v from table_test lateral view posexplode_outer(score) tmp as k,v order by id;
+------+----------+--------------------------------+------+---------+
| id | name | score | k | v |
+------+----------+--------------------------------+------+---------+
| 0 | zhangsan | ["Chinese", "Math", "English"] | 0 | Chinese |
| 0 | zhangsan | ["Chinese", "Math", "English"] | 1 | Math |
| 0 | zhangsan | ["Chinese", "Math", "English"] | 2 | English |
| 1 | lisi | ["null"] | 0 | null |
| 2 | wangwu | ["88a", "90b", "96c"] | 0 | 88a |
| 2 | wangwu | ["88a", "90b", "96c"] | 1 | 90b |
| 2 | wangwu | ["88a", "90b", "96c"] | 2 | 96c |
| 3 | lisi2 | [null] | 0 | NULL |
| 4 | amory | NULL | NULL | NULL |
+------+----------+--------------------------------+------+---------+
SELECT id, e1
FROM json_array_example
LATERAL VIEW EXPLODE_JSON_ARRAY_DOUBLE_OUTER(json_array) tmp1 AS e1
WHERE id = 6;
```

### Keywords
POSEXPLODE,POSEXPLODE_OUTER
```text
+------+------+
| id | e1 |
+------+------+
| 6 | NULL |
+------+------+
```
Loading

0 comments on commit 10770d0

Please sign in to comment.