Transforming Complex Data Types - SQL(SQL)

Loading...

Transforming Complex Data Types in Spark SQL

In this notebook we're going to go through some data transformation examples using Spark SQL. Spark SQL supports many built-in transformation functions natively in SQL.

%python
 
from pyspark.sql.functions import *
from pyspark.sql.types import *
 
# Convenience function for turning JSON strings into DataFrames.
def jsonToDataFrame(json, schema=None):
  # SparkSessions are available with Spark 2.0+
  reader = spark.read
  if schema:
    reader.schema(schema)
  reader.json(sc.parallelize([json])).createOrReplaceTempView("events")

Selecting from nested columns - Dots (".") can be used to access nested columns for structs and maps.

%python
 
# Using a struct
schema = StructType().add("a", StructType().add("b", IntegerType()))
                          
jsonToDataFrame("""
{
  "a": {
     "b": 1
  }
}
""", schema)
select a.b from events
 
b
1
1

Showing all 1 rows.

%python
 
# Using a map
schema = StructType().add("a", MapType(StringType(), IntegerType()))
                          
jsonToDataFrame("""
{
  "a": {
     "b": 1
  }
}
""", schema)
select a.b from events
 
b
1
1

Showing all 1 rows.

Flattening structs - A star ("*") can be used to select all of the subfields in a struct.

%python
 
jsonToDataFrame("""
{
  "a": {
     "b": 1,
     "c": 2
  }
}
""")
select a.* from events
 
b
c
1
1
2

Showing all 1 rows.

Nesting columns - The struct() function or just parentheses in SQL can be used to create a new struct.

%python
 
jsonToDataFrame("""
{
  "a": 1,
  "b": 2,
  "c": 3
}
""")
select named_struct("y", a) as x from events
 
x
1
{"y": 1}

Showing all 1 rows.

Nesting all columns - The star ("*") can also be used to include all columns in a nested struct.

%python
 
jsonToDataFrame("""
{
  "a": 1,
  "b": 2
}
""")
select struct(*) as x from events
 
x
1
{"a": 1, "b": 2}

Showing all 1 rows.

Selecting a single array or map element - getItem() or square brackets (i.e. [ ]) can be used to select a single element out of an array or a map.

%python
 
jsonToDataFrame("""
{
  "a": [1, 2]
}
""")
select a[0] as x from events
 
x
1
1

Showing all 1 rows.

%python
 
# Using a map
schema = StructType().add("a", MapType(StringType(), IntegerType()))
 
jsonToDataFrame("""
{
  "a": {
    "b": 1
  }
}
""", schema)
select a['b'] as x from events
 
x
1
1

Showing all 1 rows.

Creating a row for each array or map element - explode() can be used to create a new row for each element in an array or each key-value pair. This is similar to LATERAL VIEW EXPLODE in HiveQL.

%python
 
jsonToDataFrame("""
{
  "a": [1, 2]
}
""")
select explode(a) as x from events
 
x
1
2
1
2

Showing all 2 rows.

%python
 
schema = StructType().add("a", MapType(StringType(), IntegerType()))
 
jsonToDataFrame("""
{
  "a": {
    "b": 1,
    "c": 2
  }
}
""", schema)
select explode(a) as (x, y) from events
 
x
y
1
2
b
1
c
2

Showing all 2 rows.

Collecting multiple rows into an array - collect_list() and collect_set() can be used to aggregate items into an array.

%python
 
jsonToDataFrame("""
[{ "x": 1 }, { "x": 2 }]
""")
select collect_list(x) as x from events
 
x
1
[1, 2]

Showing all 1 rows.

%python
 
jsonToDataFrame("""
[{ "x": 1, "y": "a" }, { "x": 2, "y": "b" }]
""")
 
select y, collect_list(x) as x from events group by y
 
y
x
1
2
b
[2]
a
[1]

Showing all 2 rows.

Selecting one field from each item in an array - when you use dot notation on an array we return a new array where that field has been selected from each array element.

%python
 
jsonToDataFrame("""
{
  "a": [
    {"b": 1},
    {"b": 2}
  ]
}
""")
select a.b from events
 
b
1
[1, 2]

Showing all 1 rows.

Parse a set of fields from a column containing json - json_tuple() can be used to extract a fields available in a string column with json data.

%python
 
jsonToDataFrame("""
{
  "a": "{\\"b\\":1}"
}
""")
select json_tuple(a, "b") as c from events
 
c
1
1

Showing all 1 rows.

Parse a well formed string column - regexp_extract() can be used to parse strings using regular expressions.

%python
 
jsonToDataFrame("""
[{ "a": "x: 1" }, { "a": "y: 2" }]
""")
select regexp_extract(a, "([a-z]):", 1) as c from events
 
c
1
2
x
y

Showing all 2 rows.