2025-02-13 06:15:54 +01:00
from sqlglot import ParseError , transpile
from tests . dialects . test_dialect import Validator
class TestPostgres ( Validator ) :
2025-02-13 15:01:11 +01:00
maxDiff = None
2025-02-13 06:15:54 +01:00
dialect = " postgres "
def test_ddl ( self ) :
2025-02-13 14:55:11 +01:00
self . validate_identity ( " CREATE TABLE test (foo HSTORE) " )
self . validate_identity ( " CREATE TABLE test (foo JSONB) " )
self . validate_identity ( " CREATE TABLE test (foo VARCHAR(64)[]) " )
2025-02-13 06:15:54 +01:00
self . validate_all (
" CREATE TABLE products (product_no INT UNIQUE, name TEXT, price DECIMAL) " ,
2025-02-13 14:52:26 +01:00
write = {
" postgres " : " CREATE TABLE products (product_no INT UNIQUE, name TEXT, price DECIMAL) "
} ,
2025-02-13 06:15:54 +01:00
)
self . validate_all (
" CREATE TABLE products (product_no INT CONSTRAINT must_be_different UNIQUE, name TEXT CONSTRAINT present NOT NULL, price DECIMAL) " ,
write = {
" postgres " : " CREATE TABLE products (product_no INT CONSTRAINT must_be_different UNIQUE, name TEXT CONSTRAINT present NOT NULL, price DECIMAL) "
} ,
)
self . validate_all (
" CREATE TABLE products (product_no INT, name TEXT, price DECIMAL, UNIQUE (product_no, name)) " ,
write = {
" postgres " : " CREATE TABLE products (product_no INT, name TEXT, price DECIMAL, UNIQUE (product_no, name)) "
} ,
)
self . validate_all (
" CREATE TABLE products ( "
" product_no INT UNIQUE, "
" name TEXT, "
" price DECIMAL CHECK (price > 0), "
" discounted_price DECIMAL CONSTRAINT positive_discount CHECK (discounted_price > 0), "
" CHECK (product_no > 1), "
" CONSTRAINT valid_discount CHECK (price > discounted_price)) " ,
write = {
" postgres " : " CREATE TABLE products ( "
" product_no INT UNIQUE, "
" name TEXT, "
" price DECIMAL CHECK (price > 0), "
" discounted_price DECIMAL CONSTRAINT positive_discount CHECK (discounted_price > 0), "
" CHECK (product_no > 1), "
" CONSTRAINT valid_discount CHECK (price > discounted_price)) "
} ,
)
with self . assertRaises ( ParseError ) :
2025-02-13 07:47:22 +01:00
transpile ( " CREATE TABLE products (price DECIMAL CHECK price > 0) " , read = " postgres " )
2025-02-13 06:15:54 +01:00
with self . assertRaises ( ParseError ) :
transpile (
" CREATE TABLE products (price DECIMAL, CHECK price > 1) " ,
read = " postgres " ,
)
def test_postgres ( self ) :
2025-02-13 15:07:44 +01:00
self . validate_all (
" x ^ y " ,
write = {
" " : " POWER(x, y) " ,
" postgres " : " x ^ y " ,
} ,
)
self . validate_all (
" x # y " ,
write = {
" " : " x ^ y " ,
" postgres " : " x # y " ,
} ,
)
2025-02-13 14:55:11 +01:00
self . validate_identity ( " SELECT ARRAY[1, 2, 3] " )
2025-02-13 15:07:44 +01:00
self . validate_identity ( " SELECT ARRAY(SELECT 1) " )
2025-02-13 14:55:11 +01:00
self . validate_identity ( " SELECT ARRAY_LENGTH(ARRAY[1, 2, 3], 1) " )
self . validate_identity ( " STRING_AGG(x, y) " )
self . validate_identity ( " STRING_AGG(x, ' , ' ORDER BY y) " )
self . validate_identity ( " STRING_AGG(x, ' , ' ORDER BY y DESC) " )
self . validate_identity ( " STRING_AGG(DISTINCT x, ' , ' ORDER BY y DESC) " )
2025-02-13 07:47:22 +01:00
self . validate_identity ( " SELECT CASE WHEN SUBSTRING( ' abcdefg ' ) IN ( ' ab ' ) THEN 1 ELSE 0 END " )
2025-02-13 14:52:26 +01:00
self . validate_identity (
" SELECT CASE WHEN SUBSTRING( ' abcdefg ' FROM 1) IN ( ' ab ' ) THEN 1 ELSE 0 END "
)
self . validate_identity (
" SELECT CASE WHEN SUBSTRING( ' abcdefg ' FROM 1 FOR 2) IN ( ' ab ' ) THEN 1 ELSE 0 END "
)
self . validate_identity (
' SELECT * FROM " x " WHERE SUBSTRING( " x " . " foo " FROM 1 FOR 2) IN ( \' mas \' ) '
)
2025-02-13 07:47:22 +01:00
self . validate_identity ( " SELECT * FROM x WHERE SUBSTRING( ' Thomas ' FROM ' ...$ ' ) IN ( ' mas ' ) " )
2025-02-13 14:52:26 +01:00
self . validate_identity (
" SELECT * FROM x WHERE SUBSTRING( ' Thomas ' FROM ' % # \" o_a# \" _ ' FOR ' # ' ) IN ( ' mas ' ) "
)
self . validate_identity (
" SELECT SUBSTRING( ' bla ' + ' foo ' || ' bar ' FROM 3 - 1 + 5 FOR 4 + SOME_FUNC(arg1, arg2)) "
)
2025-02-13 07:47:22 +01:00
self . validate_identity ( " SELECT TRIM( ' X ' FROM ' XXX ' ) " )
self . validate_identity ( " SELECT TRIM(LEADING ' bla ' FROM ' XXX ' COLLATE utf8_bin) " )
2025-02-13 14:52:26 +01:00
self . validate_identity (
" SELECT TO_TIMESTAMP(1284352323.5), TO_TIMESTAMP( ' 05 Dec 2000 ' , ' DD Mon YYYY ' ) "
)
2025-02-13 14:46:14 +01:00
self . validate_identity ( " COMMENT ON TABLE mytable IS ' this ' " )
2025-02-13 14:47:39 +01:00
self . validate_identity ( " SELECT e ' \\ xDEADBEEF ' " )
self . validate_identity ( " SELECT CAST(e ' \\ 176 ' AS BYTEA) " )
2025-02-13 15:01:11 +01:00
self . validate_identity ( """ SELECT * FROM JSON_TO_RECORDSET(z) AS y( " rank " INT) """ )
2025-02-13 15:07:44 +01:00
self . validate_identity (
" SELECT SUM(x) OVER a, SUM(y) OVER b FROM c WINDOW a AS (PARTITION BY d), b AS (PARTITION BY e) "
)
self . validate_identity (
" CREATE TABLE A (LIKE B INCLUDING CONSTRAINT INCLUDING COMPRESSION EXCLUDING COMMENTS) "
)
self . validate_identity ( " x ~ ' y ' " )
self . validate_identity ( " x ~* ' y ' " )
2025-02-13 07:47:22 +01:00
2025-02-13 14:55:11 +01:00
self . validate_all (
" END WORK AND NO CHAIN " ,
write = { " postgres " : " COMMIT AND NO CHAIN " } ,
)
self . validate_all (
" END AND CHAIN " ,
write = { " postgres " : " COMMIT AND CHAIN " } ,
)
2025-02-13 06:15:54 +01:00
self . validate_all (
" CREATE TABLE x (a UUID, b BYTEA) " ,
write = {
2025-02-13 14:52:26 +01:00
" duckdb " : " CREATE TABLE x (a UUID, b VARBINARY) " ,
2025-02-13 06:15:54 +01:00
" presto " : " CREATE TABLE x (a UUID, b VARBINARY) " ,
" hive " : " CREATE TABLE x (a UUID, b BINARY) " ,
" spark " : " CREATE TABLE x (a UUID, b BINARY) " ,
} ,
)
2025-02-13 15:01:11 +01:00
self . validate_all (
" 123::CHARACTER VARYING " ,
write = { " postgres " : " CAST(123 AS VARCHAR) " } ,
)
self . validate_all (
" TO_TIMESTAMP(123::DOUBLE PRECISION) " ,
write = { " postgres " : " TO_TIMESTAMP(CAST(123 AS DOUBLE PRECISION)) " } ,
)
2025-02-13 15:02:59 +01:00
self . validate_all (
" SELECT to_timestamp(123)::time without time zone " ,
write = { " postgres " : " SELECT CAST(TO_TIMESTAMP(123) AS TIME) " } ,
)
2025-02-13 06:15:54 +01:00
self . validate_all (
" SELECT SUM(x) OVER (PARTITION BY a ORDER BY d ROWS 1 PRECEDING) " ,
write = {
" postgres " : " SELECT SUM(x) OVER (PARTITION BY a ORDER BY d ROWS BETWEEN 1 PRECEDING AND CURRENT ROW) " ,
} ,
)
self . validate_all (
" SELECT * FROM x FETCH 1 ROW " ,
write = {
" postgres " : " SELECT * FROM x FETCH FIRST 1 ROWS ONLY " ,
" presto " : " SELECT * FROM x FETCH FIRST 1 ROWS ONLY " ,
" hive " : " SELECT * FROM x FETCH FIRST 1 ROWS ONLY " ,
" spark " : " SELECT * FROM x FETCH FIRST 1 ROWS ONLY " ,
} ,
)
self . validate_all (
" SELECT fname, lname, age FROM person ORDER BY age DESC NULLS FIRST, fname ASC NULLS LAST, lname " ,
write = {
" postgres " : " SELECT fname, lname, age FROM person ORDER BY age DESC, fname, lname " ,
" presto " : " SELECT fname, lname, age FROM person ORDER BY age DESC NULLS FIRST, fname, lname " ,
" hive " : " SELECT fname, lname, age FROM person ORDER BY age DESC NULLS FIRST, fname NULLS LAST, lname NULLS LAST " ,
" spark " : " SELECT fname, lname, age FROM person ORDER BY age DESC NULLS FIRST, fname NULLS LAST, lname NULLS LAST " ,
} ,
)
2025-02-13 07:47:22 +01:00
self . validate_all (
" SELECT CASE WHEN SUBSTRING( ' abcdefg ' FROM 1 FOR 2) IN ( ' ab ' ) THEN 1 ELSE 0 END " ,
write = {
" hive " : " SELECT CASE WHEN SUBSTRING( ' abcdefg ' , 1, 2) IN ( ' ab ' ) THEN 1 ELSE 0 END " ,
" spark " : " SELECT CASE WHEN SUBSTRING( ' abcdefg ' , 1, 2) IN ( ' ab ' ) THEN 1 ELSE 0 END " ,
} ,
)
self . validate_all (
" SELECT * FROM x WHERE SUBSTRING(col1 FROM 3 + LENGTH(col1) - 10 FOR 10) IN (col2) " ,
write = {
" hive " : " SELECT * FROM x WHERE SUBSTRING(col1, 3 + LENGTH(col1) - 10, 10) IN (col2) " ,
" spark " : " SELECT * FROM x WHERE SUBSTRING(col1, 3 + LENGTH(col1) - 10, 10) IN (col2) " ,
} ,
)
self . validate_all (
" SELECT SUBSTRING(CAST(2022 AS CHAR(4)) || LPAD(CAST(3 AS CHAR(2)), 2, ' 0 ' ) FROM 3 FOR 4) " ,
read = {
" postgres " : " SELECT SUBSTRING(2022::CHAR(4) || LPAD(3::CHAR(2), 2, ' 0 ' ) FROM 3 FOR 4) " ,
} ,
)
self . validate_all (
" SELECT TRIM(BOTH ' XXX ' ) " ,
write = {
" mysql " : " SELECT TRIM( ' XXX ' ) " ,
" postgres " : " SELECT TRIM( ' XXX ' ) " ,
" hive " : " SELECT TRIM( ' XXX ' ) " ,
} ,
)
self . validate_all (
" TRIM(LEADING FROM ' XXX ' ) " ,
write = {
" mysql " : " LTRIM( ' XXX ' ) " ,
" postgres " : " LTRIM( ' XXX ' ) " ,
" hive " : " LTRIM( ' XXX ' ) " ,
" presto " : " LTRIM( ' XXX ' ) " ,
} ,
)
self . validate_all (
" TRIM(TRAILING FROM ' XXX ' ) " ,
write = {
" mysql " : " RTRIM( ' XXX ' ) " ,
" postgres " : " RTRIM( ' XXX ' ) " ,
" hive " : " RTRIM( ' XXX ' ) " ,
" presto " : " RTRIM( ' XXX ' ) " ,
} ,
)
self . validate_all (
" SELECT * FROM foo, LATERAL (SELECT * FROM bar WHERE bar.id = foo.bar_id) AS ss " ,
2025-02-13 14:52:26 +01:00
read = {
" postgres " : " SELECT * FROM foo, LATERAL (SELECT * FROM bar WHERE bar.id = foo.bar_id) AS ss "
} ,
2025-02-13 07:47:22 +01:00
)
self . validate_all (
2025-02-13 15:01:11 +01:00
" SELECT m.name FROM manufacturers AS m LEFT JOIN LATERAL GET_PRODUCT_NAMES(m.id) pname ON TRUE WHERE pname IS NULL " ,
write = {
2025-02-13 07:47:22 +01:00
" postgres " : " SELECT m.name FROM manufacturers AS m LEFT JOIN LATERAL GET_PRODUCT_NAMES(m.id) AS pname ON TRUE WHERE pname IS NULL " ,
} ,
)
self . validate_all (
" SELECT p1.id, p2.id, v1, v2 FROM polygons AS p1, polygons AS p2, LATERAL VERTICES(p1.poly) v1, LATERAL VERTICES(p2.poly) v2 WHERE (v1 <-> v2) < 10 AND p1.id <> p2.id " ,
2025-02-13 15:01:11 +01:00
write = {
" postgres " : " SELECT p1.id, p2.id, v1, v2 FROM polygons AS p1, polygons AS p2, LATERAL VERTICES(p1.poly) AS v1, LATERAL VERTICES(p2.poly) AS v2 WHERE (v1 <-> v2) < 10 AND p1.id <> p2.id " ,
} ,
)
self . validate_all (
" SELECT * FROM r CROSS JOIN LATERAL unnest(array(1)) AS s(location) " ,
write = {
" postgres " : " SELECT * FROM r CROSS JOIN LATERAL UNNEST(ARRAY[1]) AS s(location) " ,
2025-02-13 07:47:22 +01:00
} ,
)
2025-02-13 14:46:14 +01:00
self . validate_all (
" SELECT id, email, CAST(deleted AS TEXT) FROM users WHERE NOT deleted IS NULL " ,
2025-02-13 14:52:26 +01:00
read = {
" postgres " : " SELECT id, email, CAST(deleted AS TEXT) FROM users WHERE deleted NOTNULL "
} ,
2025-02-13 14:46:14 +01:00
)
self . validate_all (
" SELECT id, email, CAST(deleted AS TEXT) FROM users WHERE NOT deleted IS NULL " ,
2025-02-13 14:52:26 +01:00
read = {
" postgres " : " SELECT id, email, CAST(deleted AS TEXT) FROM users WHERE NOT deleted ISNULL "
} ,
2025-02-13 14:46:14 +01:00
)
self . validate_all (
" ' [1,2,3] ' ::json->2 " ,
2025-02-13 15:01:11 +01:00
write = { " postgres " : " CAST( ' [1,2,3] ' AS JSON) -> ' 2 ' " } ,
2025-02-13 14:46:14 +01:00
)
self . validate_all (
""" ' { " a " :1, " b " :2} ' ::json-> ' b ' """ ,
2025-02-13 15:01:11 +01:00
write = { " postgres " : """ CAST( ' { " a " :1, " b " :2} ' AS JSON) -> ' b ' """ } ,
2025-02-13 14:46:14 +01:00
)
self . validate_all (
2025-02-13 14:52:26 +01:00
""" ' { " x " : { " y " : 1}} ' ::json-> ' x ' -> ' y ' """ ,
2025-02-13 15:01:11 +01:00
write = { " postgres " : """ CAST( ' { " x " : { " y " : 1}} ' AS JSON) -> ' x ' -> ' y ' """ } ,
2025-02-13 14:46:14 +01:00
)
self . validate_all (
""" ' { " x " : { " y " : 1}} ' ::json-> ' x ' ::json-> ' y ' """ ,
2025-02-13 15:01:11 +01:00
write = { " postgres " : """ CAST(CAST( ' { " x " : { " y " : 1}} ' AS JSON) -> ' x ' AS JSON) -> ' y ' """ } ,
2025-02-13 14:46:14 +01:00
)
self . validate_all (
""" ' [1,2,3] ' ::json->>2 """ ,
2025-02-13 15:01:11 +01:00
write = { " postgres " : " CAST( ' [1,2,3] ' AS JSON) ->> ' 2 ' " } ,
2025-02-13 14:46:14 +01:00
)
self . validate_all (
""" ' { " a " :1, " b " :2} ' ::json->> ' b ' """ ,
2025-02-13 15:01:11 +01:00
write = { " postgres " : """ CAST( ' { " a " :1, " b " :2} ' AS JSON) ->> ' b ' """ } ,
2025-02-13 14:46:14 +01:00
)
self . validate_all (
""" ' { " a " :[1,2,3], " b " :[4,5,6]} ' ::json#> ' { a,2} ' """ ,
2025-02-13 15:01:11 +01:00
write = { " postgres " : """ CAST( ' { " a " :[1,2,3], " b " :[4,5,6]} ' AS JSON) #> ' { a,2} ' """ } ,
2025-02-13 14:46:14 +01:00
)
self . validate_all (
""" ' { " a " :[1,2,3], " b " :[4,5,6]} ' ::json#>> ' { a,2} ' """ ,
2025-02-13 15:01:11 +01:00
write = { " postgres " : """ CAST( ' { " a " :[1,2,3], " b " :[4,5,6]} ' AS JSON) #>> ' { a,2} ' """ } ,
)
self . validate_all (
""" SELECT JSON_ARRAY_ELEMENTS((foo-> ' sections ' )::JSON) AS sections """ ,
write = {
" postgres " : """ SELECT JSON_ARRAY_ELEMENTS(CAST((foo -> ' sections ' ) AS JSON)) AS sections """ ,
" presto " : """ SELECT JSON_ARRAY_ELEMENTS(CAST((JSON_EXTRACT(foo, ' sections ' )) AS JSON)) AS sections """ ,
} ,
)
self . validate_all (
""" x ? ' x ' """ ,
write = { " postgres " : " x ? ' x ' " } ,
2025-02-13 14:46:14 +01:00
)
2025-02-13 14:47:39 +01:00
self . validate_all (
" SELECT $$a$$ " ,
write = { " postgres " : " SELECT ' a ' " } ,
)
self . validate_all (
" SELECT $$Dianne ' s horse$$ " ,
write = { " postgres " : " SELECT ' Dianne ' ' s horse ' " } ,
)
2025-02-13 14:57:38 +01:00
self . validate_all (
" UPDATE MYTABLE T1 SET T1.COL = 13 " ,
write = { " postgres " : " UPDATE MYTABLE AS T1 SET T1.COL = 13 " } ,
)
2025-02-13 15:01:11 +01:00
self . validate_all (
" x !~ ' y ' " ,
write = { " postgres " : " NOT x ~ ' y ' " } ,
)
self . validate_all (
" x !~* ' y ' " ,
write = { " postgres " : " NOT x ~* ' y ' " } ,
)
self . validate_all (
" x ~~ ' y ' " ,
write = { " postgres " : " x LIKE ' y ' " } ,
)
self . validate_all (
" x ~~* ' y ' " ,
write = { " postgres " : " x ILIKE ' y ' " } ,
)
self . validate_all (
" x !~~ ' y ' " ,
write = { " postgres " : " NOT x LIKE ' y ' " } ,
)
self . validate_all (
" x !~~* ' y ' " ,
write = { " postgres " : " NOT x ILIKE ' y ' " } ,
)
self . validate_all (
" ' 45 days ' ::interval day " ,
write = { " postgres " : " CAST( ' 45 days ' AS INTERVAL day) " } ,
)
self . validate_all (
" ' x ' ' y ' ' z ' " ,
write = { " postgres " : " CONCAT( ' x ' , ' y ' , ' z ' ) " } ,
)
self . validate_all (
" x::cstring " ,
write = { " postgres " : " CAST(x AS CSTRING) " } ,
)
2025-02-13 15:07:44 +01:00
self . validate_all (
" TRIM(BOTH ' as ' FROM ' as string as ' ) " ,
write = {
" postgres " : " TRIM(BOTH ' as ' FROM ' as string as ' ) " ,
" spark " : " TRIM(BOTH ' as ' FROM ' as string as ' ) " ,
} ,
)
2025-02-13 15:01:11 +01:00
2025-02-13 15:07:44 +01:00
def test_bool_or ( self ) :
self . validate_all (
" SELECT a, LOGICAL_OR(b) FROM table GROUP BY a " ,
write = { " postgres " : " SELECT a, BOOL_OR(b) FROM table GROUP BY a " } ,
2025-02-13 15:01:11 +01:00
)