2025-02-13 21:54:13 +01:00
from sqlglot . errors import UnsupportedError
2025-02-13 06:15:54 +01:00
from tests . dialects . test_dialect import Validator
2025-02-13 20:51:40 +01:00
class TestStarrocks ( Validator ) :
2025-02-13 06:15:54 +01:00
dialect = " starrocks "
2025-02-13 21:56:02 +01:00
def test_starrocks ( self ) :
self . validate_identity ( " ALTER TABLE a SWAP WITH b " )
2025-02-13 21:54:13 +01:00
def test_ddl ( self ) :
ddl_sqls = [
" DISTRIBUTED BY HASH (col1) BUCKETS 1 " ,
" DISTRIBUTED BY HASH (col1) " ,
" DISTRIBUTED BY RANDOM BUCKETS 1 " ,
" DISTRIBUTED BY RANDOM " ,
" DISTRIBUTED BY HASH (col1) ORDER BY (col1) " ,
" DISTRIBUTED BY HASH (col1) PROPERTIES ( ' replication_num ' = ' 1 ' ) " ,
" PRIMARY KEY (col1) DISTRIBUTED BY HASH (col1) " ,
" DUPLICATE KEY (col1, col2) DISTRIBUTED BY HASH (col1) " ,
]
for properties in ddl_sqls :
with self . subTest ( f " Testing create scheme: { properties } " ) :
self . validate_identity ( f " CREATE TABLE foo (col1 BIGINT, col2 BIGINT) { properties } " )
self . validate_identity (
f " CREATE TABLE foo (col1 BIGINT, col2 BIGINT) ENGINE=OLAP { properties } "
)
# Test the different wider DECIMAL types
self . validate_identity (
" CREATE TABLE foo (col0 DECIMAL(9, 1), col1 DECIMAL32(9, 1), col2 DECIMAL64(18, 10), col3 DECIMAL128(38, 10)) DISTRIBUTED BY HASH (col1) BUCKETS 1 "
)
2025-02-13 06:15:54 +01:00
def test_identity ( self ) :
self . validate_identity ( " SELECT CAST(`a`.`b` AS INT) FROM foo " )
2025-02-13 15:52:09 +01:00
self . validate_identity ( " SELECT APPROX_COUNT_DISTINCT(a) FROM x " )
2025-02-13 21:52:55 +01:00
self . validate_identity ( " SELECT [1, 2, 3] " )
2025-02-13 21:54:13 +01:00
self . validate_identity (
""" SELECT CAST(PARSE_JSON(fieldvalue) -> ' 00000000-0000-0000-0000-00000000 ' AS VARCHAR) AS `code` FROM (SELECT ' { " 00000000-0000-0000-0000-00000000 " : " code01 " } ' ) AS t(fieldvalue) """
)
2025-02-13 21:57:20 +01:00
self . validate_identity (
" SELECT text FROM example_table " , write_sql = " SELECT `text` FROM example_table "
)
2025-02-13 14:53:05 +01:00
def test_time ( self ) :
self . validate_identity ( " TIMESTAMP( ' 2022-01-01 ' ) " )
2025-02-13 20:51:40 +01:00
self . validate_identity (
2025-02-13 21:19:14 +01:00
" SELECT DATE_DIFF( ' SECOND ' , ' 2010-11-30 23:59:59 ' , ' 2010-11-30 20:58:59 ' ) "
2025-02-13 20:51:40 +01:00
)
self . validate_identity (
2025-02-13 21:19:14 +01:00
" SELECT DATE_DIFF( ' MINUTE ' , ' 2010-11-30 23:59:59 ' , ' 2010-11-30 20:58:59 ' ) "
2025-02-13 20:51:40 +01:00
)
2025-02-13 15:53:39 +01:00
def test_regex ( self ) :
self . validate_all (
2025-02-13 20:51:40 +01:00
" SELECT REGEXP(abc, ' %f oo % ' ) " ,
read = {
" mysql " : " SELECT REGEXP_LIKE(abc, ' %f oo % ' ) " ,
2025-02-13 15:53:39 +01:00
" starrocks " : " SELECT REGEXP(abc, ' %f oo % ' ) " ,
} ,
2025-02-13 20:51:40 +01:00
write = {
" mysql " : " SELECT REGEXP_LIKE(abc, ' %f oo % ' ) " ,
} ,
2025-02-13 15:53:39 +01:00
)
2025-02-13 21:52:55 +01:00
def test_unnest ( self ) :
self . validate_identity (
" SELECT student, score, t.unnest FROM tests CROSS JOIN LATERAL UNNEST(scores) AS t " ,
" SELECT student, score, t.unnest FROM tests CROSS JOIN LATERAL UNNEST(scores) AS t(unnest) " ,
)
2025-02-13 21:54:13 +01:00
self . validate_all (
" SELECT student, score, unnest FROM tests CROSS JOIN LATERAL UNNEST(scores) " ,
write = {
" spark " : " SELECT student, score, unnest FROM tests LATERAL VIEW EXPLODE(scores) unnest AS unnest " ,
" starrocks " : " SELECT student, score, unnest FROM tests CROSS JOIN LATERAL UNNEST(scores) AS unnest(unnest) " ,
} ,
)
self . validate_all (
r """ SELECT * FROM UNNEST(array[ ' John ' , ' Jane ' , ' Jim ' , ' Jamie ' ], array[24,25,26,27]) AS t(name, age) """ ,
write = {
" postgres " : " SELECT * FROM UNNEST(ARRAY[ ' John ' , ' Jane ' , ' Jim ' , ' Jamie ' ], ARRAY[24, 25, 26, 27]) AS t(name, age) " ,
" spark " : " SELECT * FROM INLINE(ARRAYS_ZIP(ARRAY( ' John ' , ' Jane ' , ' Jim ' , ' Jamie ' ), ARRAY(24, 25, 26, 27))) AS t(name, age) " ,
" starrocks " : " SELECT * FROM UNNEST([ ' John ' , ' Jane ' , ' Jim ' , ' Jamie ' ], [24, 25, 26, 27]) AS t(name, age) " ,
} ,
)
# Use UNNEST to convert into multiple columns
# see: https://docs.starrocks.io/docs/sql-reference/sql-functions/array-functions/unnest/
self . validate_all (
r """ SELECT id, t.type, t.scores FROM example_table, unnest(split(type, " ; " ), scores) AS t(type,scores) """ ,
write = {
" postgres " : " SELECT id, t.type, t.scores FROM example_table, UNNEST(SPLIT(type, ' ; ' ), scores) AS t(type, scores) " ,
2025-02-13 21:55:19 +01:00
" spark " : r """ SELECT id, t.type, t.scores FROM example_table LATERAL VIEW INLINE(ARRAYS_ZIP(SPLIT(type, CONCAT( ' \ \ Q ' , ' ; ' , ' \ \ E ' )), scores)) t AS type, scores """ ,
" databricks " : r """ SELECT id, t.type, t.scores FROM example_table LATERAL VIEW INLINE(ARRAYS_ZIP(SPLIT(type, CONCAT( ' \ \ Q ' , ' ; ' , ' \ \ E ' )), scores)) t AS type, scores """ ,
2025-02-13 21:54:13 +01:00
" starrocks " : r """ SELECT id, t.type, t.scores FROM example_table, UNNEST(SPLIT(type, ' ; ' ), scores) AS t(type, scores) """ ,
" hive " : UnsupportedError ,
} ,
)
self . validate_all (
r """ SELECT id, t.type, t.scores FROM example_table_2 CROSS JOIN LATERAL unnest(split(type, " ; " ), scores) AS t(type,scores) """ ,
write = {
2025-02-13 21:55:19 +01:00
" spark " : r """ SELECT id, t.type, t.scores FROM example_table_2 LATERAL VIEW INLINE(ARRAYS_ZIP(SPLIT(type, CONCAT( ' \ \ Q ' , ' ; ' , ' \ \ E ' )), scores)) t AS type, scores """ ,
2025-02-13 21:54:13 +01:00
" starrocks " : r """ SELECT id, t.type, t.scores FROM example_table_2 CROSS JOIN LATERAL UNNEST(SPLIT(type, ' ; ' ), scores) AS t(type, scores) """ ,
" hive " : UnsupportedError ,
} ,
)
2025-02-13 21:52:55 +01:00
lateral_explode_sqls = [
" SELECT id, t.col FROM tbl, UNNEST(scores) AS t(col) " ,
" SELECT id, t.col FROM tbl CROSS JOIN LATERAL UNNEST(scores) AS t(col) " ,
]
for sql in lateral_explode_sqls :
with self . subTest ( f " Testing Starrocks roundtrip & transpilation of: { sql } " ) :
self . validate_all (
sql ,
write = {
" starrocks " : sql ,
" spark " : " SELECT id, t.col FROM tbl LATERAL VIEW EXPLODE(scores) t AS col " ,
} ,
)