SQLGlot
SQLGlot is a no-dependency SQL parser, transpiler, optimizer, and engine. It can be used to format SQL or translate between 19 different dialects like DuckDB, Presto, Spark, Snowflake, and BigQuery. It aims to read a wide variety of SQL inputs and output syntactically correct SQL in the targeted dialects.
It is a very comprehensive generic SQL parser with a robust test suite. It is also quite performant, while being written purely in Python.
You can easily customize the parser, analyze queries, traverse expression trees, and programmatically build SQL.
Syntax errors are highlighted and dialect incompatibilities can warn or raise depending on configurations. However, it should be noted that SQL validation is not SQLGlot’s goal, so some syntax errors may go unnoticed.
Contributions are very welcome in SQLGlot; read the contribution guide to get started!
Table of Contents
- Install
- Get in Touch
- Examples
- Used By
- Documentation
- Run Tests and Lint
- Benchmarks
- Optional Dependencies
Install
From PyPI:
pip3 install sqlglot
Or with a local checkout:
make install
Requirements for development (optional):
make install-dev
Get in Touch
We'd love to hear from you. Join our community Slack channel!
Examples
Formatting and Transpiling
Easily translate from one dialect to another. For example, date/time functions vary from dialects and can be hard to deal with:
import sqlglot
sqlglot.transpile("SELECT EPOCH_MS(1618088028295)", read="duckdb", write="hive")[0]
'SELECT FROM_UNIXTIME(1618088028295 / 1000)'
SQLGlot can even translate custom time formats:
import sqlglot
sqlglot.transpile("SELECT STRFTIME(x, '%y-%-m-%S')", read="duckdb", write="hive")[0]
"SELECT DATE_FORMAT(x, 'yy-M-ss')"
As another example, let's suppose that we want to read in a SQL query that contains a CTE and a cast to REAL
, and then transpile it to Spark, which uses backticks for identifiers and FLOAT
instead of REAL
:
import sqlglot
sql = """WITH baz AS (SELECT a, c FROM foo WHERE a = 1) SELECT f.a, b.b, baz.c, CAST("b"."a" AS REAL) d FROM foo f JOIN bar b ON f.a = b.a LEFT JOIN baz ON f.a = baz.a"""
print(sqlglot.transpile(sql, write="spark", identify=True, pretty=True)[0])
WITH `baz` AS (
SELECT
`a`,
`c`
FROM `foo`
WHERE
`a` = 1
)
SELECT
`f`.`a`,
`b`.`b`,
`baz`.`c`,
CAST(`b`.`a` AS FLOAT) AS `d`
FROM `foo` AS `f`
JOIN `bar` AS `b`
ON `f`.`a` = `b`.`a`
LEFT JOIN `baz`
ON `f`.`a` = `baz`.`a`
Comments are also preserved in a best-effort basis when transpiling SQL code:
sql = """
/* multi
line
comment
*/
SELECT
tbl.cola /* comment 1 */ + tbl.colb /* comment 2 */,
CAST(x AS INT), # comment 3
y -- comment 4
FROM
bar /* comment 5 */,
tbl # comment 6
"""
print(sqlglot.transpile(sql, read='mysql', pretty=True)[0])
/* multi
line
comment
*/
SELECT
tbl.cola /* comment 1 */ + tbl.colb /* comment 2 */,
CAST(x AS INT), /* comment 3 */
y /* comment 4 */
FROM bar /* comment 5 */, tbl /* comment 6 */
Metadata
You can explore SQL with expression helpers to do things like find columns and tables:
from sqlglot import parse_one, exp
# print all column references (a and b)
for column in parse_one("SELECT a, b + 1 AS c FROM d").find_all(exp.Column):
print(column.alias_or_name)
# find all projections in select statements (a and c)
for select in parse_one("SELECT a, b + 1 AS c FROM d").find_all(exp.Select):
for projection in select.expressions:
print(projection.alias_or_name)
# find all tables (x, y, z)
for table in parse_one("SELECT * FROM x JOIN y JOIN z").find_all(exp.Table):
print(table.name)
Parser Errors
When the parser detects an error in the syntax, it raises a ParserError:
import sqlglot
sqlglot.transpile("SELECT foo( FROM bar")
sqlglot.errors.ParseError: Expecting ). Line 1, Col: 13.
select foo( FROM bar
~~~~
Structured syntax errors are accessible for programmatic use:
import sqlglot
try:
sqlglot.transpile("SELECT foo( FROM bar")
except sqlglot.errors.ParseError as e:
print(e.errors)
[{
'description': 'Expecting )',
'line': 1,
'col': 13,
'start_context': 'SELECT foo( ',
'highlight': 'FROM',
'end_context': ' bar'
}]
Unsupported Errors
Presto APPROX_DISTINCT
supports the accuracy argument which is not supported in Hive:
import sqlglot
sqlglot.transpile("SELECT APPROX_DISTINCT(a, 0.1) FROM foo", read="presto", write="hive")
APPROX_COUNT_DISTINCT does not support accuracy
'SELECT APPROX_COUNT_DISTINCT(a) FROM foo'
Build and Modify SQL
SQLGlot supports incrementally building sql expressions:
from sqlglot import select, condition
where = condition("x=1").and_("y=1")
select("*").from_("y").where(where).sql()
'SELECT * FROM y WHERE x = 1 AND y = 1'
You can also modify a parsed tree:
from sqlglot import parse_one
parse_one("SELECT x FROM y").from_("z").sql()
'SELECT x FROM y, z'
There is also a way to recursively transform the parsed tree by applying a mapping function to each tree node:
from sqlglot import exp, parse_one
expression_tree = parse_one("SELECT a FROM x")
def transformer(node):
if isinstance(node, exp.Column) and node.name == "a":
return parse_one("FUN(a)")
return node
transformed_tree = expression_tree.transform(transformer)
transformed_tree.sql()
'SELECT FUN(a) FROM x'
SQL Optimizer
SQLGlot can rewrite queries into an "optimized" form. It performs a variety of techniques to create a new canonical AST. This AST can be used to standardize queries or provide the foundations for implementing an actual engine. For example:
import sqlglot
from sqlglot.optimizer import optimize
print(
optimize(
sqlglot.parse_one("""
SELECT A OR (B OR (C AND D))
FROM x
WHERE Z = date '2021-01-01' + INTERVAL '1' month OR 1 = 0
"""),
schema={"x": {"A": "INT", "B": "INT", "C": "INT", "D": "INT", "Z": "STRING"}}
).sql(pretty=True)
)
SELECT
(
"x"."a" OR "x"."b" OR "x"."c"
) AND (
"x"."a" OR "x"."b" OR "x"."d"
) AS "_col_0"
FROM "x" AS "x"
WHERE
CAST("x"."z" AS DATE) = CAST('2021-02-01' AS DATE)
AST Introspection
You can see the AST version of the sql by calling repr
:
from sqlglot import parse_one
print(repr(parse_one("SELECT a + 1 AS z")))
(SELECT expressions:
(ALIAS this:
(ADD this:
(COLUMN this:
(IDENTIFIER this: a, quoted: False)), expression:
(LITERAL this: 1, is_string: False)), alias:
(IDENTIFIER this: z, quoted: False)))
AST Diff
SQLGlot can calculate the difference between two expressions and output changes in a form of a sequence of actions needed to transform a source expression into a target one:
from sqlglot import diff, parse_one
diff(parse_one("SELECT a + b, c, d"), parse_one("SELECT c, a - b, d"))
[
Remove(expression=(ADD this:
(COLUMN this:
(IDENTIFIER this: a, quoted: False)), expression:
(COLUMN this:
(IDENTIFIER this: b, quoted: False)))),
Insert(expression=(SUB this:
(COLUMN this:
(IDENTIFIER this: a, quoted: False)), expression:
(COLUMN this:
(IDENTIFIER this: b, quoted: False)))),
Move(expression=(COLUMN this:
(IDENTIFIER this: c, quoted: False))),
Keep(source=(IDENTIFIER this: b, quoted: False), target=(IDENTIFIER this: b, quoted: False)),
...
]
See also: Semantic Diff for SQL.
Custom Dialects
Dialects can be added by subclassing Dialect
:
from sqlglot import exp
from sqlglot.dialects.dialect import Dialect
from sqlglot.generator import Generator
from sqlglot.tokens import Tokenizer, TokenType
class Custom(Dialect):
class Tokenizer(Tokenizer):
QUOTES = ["'", '"']
IDENTIFIERS = ["`"]
KEYWORDS = {
**Tokenizer.KEYWORDS,
"INT64": TokenType.BIGINT,
"FLOAT64": TokenType.DOUBLE,
}
class Generator(Generator):
TRANSFORMS = {exp.Array: lambda self, e: f"[{self.expressions(e)}]"}
TYPE_MAPPING = {
exp.DataType.Type.TINYINT: "INT64",
exp.DataType.Type.SMALLINT: "INT64",
exp.DataType.Type.INT: "INT64",
exp.DataType.Type.BIGINT: "INT64",
exp.DataType.Type.DECIMAL: "NUMERIC",
exp.DataType.Type.FLOAT: "FLOAT64",
exp.DataType.Type.DOUBLE: "FLOAT64",
exp.DataType.Type.BOOLEAN: "BOOL",
exp.DataType.Type.TEXT: "STRING",
}
print(Dialect["custom"])
<class '__main__.Custom'>
SQL Execution
One can even interpret SQL queries using SQLGlot, where the tables are represented as Python dictionaries. Although the engine is not very fast (it's not supposed to be) and is in a relatively early stage of development, it can be useful for unit testing and running SQL natively across Python objects. Additionally, the foundation can be easily integrated with fast compute kernels (arrow, pandas). Below is an example showcasing the execution of a SELECT expression that involves aggregations and JOINs:
from sqlglot.executor import execute
tables = {
"sushi": [
{"id": 1, "price": 1.0},
{"id": 2, "price": 2.0},
{"id": 3, "price": 3.0},
],
"order_items": [
{"sushi_id": 1, "order_id": 1},
{"sushi_id": 1, "order_id": 1},
{"sushi_id": 2, "order_id": 1},
{"sushi_id": 3, "order_id": 2},
],
"orders": [
{"id": 1, "user_id": 1},
{"id": 2, "user_id": 2},
],
}
execute(
"""
SELECT
o.user_id,
SUM(s.price) AS price
FROM orders o
JOIN order_items i
ON o.id = i.order_id
JOIN sushi s
ON i.sushi_id = s.id
GROUP BY o.user_id
""",
tables=tables
)
user_id price
1 4.0
2 3.0
See also: Writing a Python SQL engine from scratch.
Used By
Documentation
SQLGlot uses pdoc to serve its API documentation:
make docs-serve
Run Tests and Lint
make check # Set SKIP_INTEGRATION=1 to skip integration tests
Benchmarks
Benchmarks run on Python 3.10.5 in seconds.
Query | sqlglot | sqlfluff | sqltree | sqlparse | moz_sql_parser | sqloxide |
---|---|---|---|---|---|---|
tpch | 0.01308 (1.0) | 1.60626 (122.7) | 0.01168 (0.893) | 0.04958 (3.791) | 0.08543 (6.531) | 0.00136 (0.104) |
short | 0.00109 (1.0) | 0.14134 (129.2) | 0.00099 (0.906) | 0.00342 (3.131) | 0.00652 (5.970) | 8.76E-5 (0.080) |
long | 0.01399 (1.0) | 2.12632 (151.9) | 0.01126 (0.805) | 0.04410 (3.151) | 0.06671 (4.767) | 0.00107 (0.076) |
crazy | 0.03969 (1.0) | 24.3777 (614.1) | 0.03917 (0.987) | 11.7043 (294.8) | 1.03280 (26.02) | 0.00625 (0.157) |
Optional Dependencies
SQLGlot uses dateutil to simplify literal timedelta expressions. The optimizer will not simplify expressions like the following if the module cannot be found:
x + interval '1' month
1""" 2.. include:: ../README.md 3 4---- 5""" 6 7from __future__ import annotations 8 9import typing as t 10 11from sqlglot import expressions as exp 12from sqlglot.dialects import Dialect, Dialects 13from sqlglot.diff import diff 14from sqlglot.errors import ErrorLevel, ParseError, TokenError, UnsupportedError 15from sqlglot.expressions import Expression 16from sqlglot.expressions import alias_ as alias 17from sqlglot.expressions import ( 18 and_, 19 column, 20 condition, 21 except_, 22 from_, 23 intersect, 24 maybe_parse, 25 not_, 26 or_, 27 select, 28 subquery, 29) 30from sqlglot.expressions import table_ as table 31from sqlglot.expressions import to_column, to_table, union 32from sqlglot.generator import Generator 33from sqlglot.parser import Parser 34from sqlglot.schema import MappingSchema, Schema 35from sqlglot.tokens import Tokenizer, TokenType 36 37if t.TYPE_CHECKING: 38 from sqlglot.dialects.dialect import DialectType 39 40 T = t.TypeVar("T", bound=Expression) 41 42 43__version__ = "11.1.3" 44 45pretty = False 46"""Whether to format generated SQL by default.""" 47 48schema = MappingSchema() 49"""The default schema used by SQLGlot (e.g. in the optimizer).""" 50 51 52def parse(sql: str, read: DialectType = None, **opts) -> t.List[t.Optional[Expression]]: 53 """ 54 Parses the given SQL string into a collection of syntax trees, one per parsed SQL statement. 55 56 Args: 57 sql: the SQL code string to parse. 58 read: the SQL dialect to apply during parsing (eg. "spark", "hive", "presto", "mysql"). 59 **opts: other `sqlglot.parser.Parser` options. 60 61 Returns: 62 The resulting syntax tree collection. 63 """ 64 dialect = Dialect.get_or_raise(read)() 65 return dialect.parse(sql, **opts) 66 67 68@t.overload 69def parse_one( 70 sql: str, 71 read: None = None, 72 into: t.Type[T] = ..., 73 **opts, 74) -> T: 75 ... 76 77 78@t.overload 79def parse_one( 80 sql: str, 81 read: DialectType, 82 into: t.Type[T], 83 **opts, 84) -> T: 85 ... 86 87 88@t.overload 89def parse_one( 90 sql: str, 91 read: None = None, 92 into: t.Union[str, t.Collection[t.Union[str, t.Type[Expression]]]] = ..., 93 **opts, 94) -> Expression: 95 ... 96 97 98@t.overload 99def parse_one( 100 sql: str, 101 read: DialectType, 102 into: t.Union[str, t.Collection[t.Union[str, t.Type[Expression]]]], 103 **opts, 104) -> Expression: 105 ... 106 107 108@t.overload 109def parse_one( 110 sql: str, 111 **opts, 112) -> Expression: 113 ... 114 115 116def parse_one( 117 sql: str, 118 read: DialectType = None, 119 into: t.Optional[exp.IntoType] = None, 120 **opts, 121) -> Expression: 122 """ 123 Parses the given SQL string and returns a syntax tree for the first parsed SQL statement. 124 125 Args: 126 sql: the SQL code string to parse. 127 read: the SQL dialect to apply during parsing (eg. "spark", "hive", "presto", "mysql"). 128 into: the SQLGlot Expression to parse into. 129 **opts: other `sqlglot.parser.Parser` options. 130 131 Returns: 132 The syntax tree for the first parsed statement. 133 """ 134 135 dialect = Dialect.get_or_raise(read)() 136 137 if into: 138 result = dialect.parse_into(into, sql, **opts) 139 else: 140 result = dialect.parse(sql, **opts) 141 142 for expression in result: 143 if not expression: 144 raise ParseError(f"No expression was parsed from '{sql}'") 145 return expression 146 else: 147 raise ParseError(f"No expression was parsed from '{sql}'") 148 149 150def transpile( 151 sql: str, 152 read: DialectType = None, 153 write: DialectType = None, 154 identity: bool = True, 155 error_level: t.Optional[ErrorLevel] = None, 156 **opts, 157) -> t.List[str]: 158 """ 159 Parses the given SQL string in accordance with the source dialect and returns a list of SQL strings transformed 160 to conform to the target dialect. Each string in the returned list represents a single transformed SQL statement. 161 162 Args: 163 sql: the SQL code string to transpile. 164 read: the source dialect used to parse the input string (eg. "spark", "hive", "presto", "mysql"). 165 write: the target dialect into which the input should be transformed (eg. "spark", "hive", "presto", "mysql"). 166 identity: if set to `True` and if the target dialect is not specified the source dialect will be used as both: 167 the source and the target dialect. 168 error_level: the desired error level of the parser. 169 **opts: other `sqlglot.generator.Generator` options. 170 171 Returns: 172 The list of transpiled SQL statements. 173 """ 174 write = write or read if identity else write 175 return [ 176 Dialect.get_or_raise(write)().generate(expression, **opts) 177 for expression in parse(sql, read, error_level=error_level) 178 ]
Whether to format generated SQL by default.
The default schema used by SQLGlot (e.g. in the optimizer).
53def parse(sql: str, read: DialectType = None, **opts) -> t.List[t.Optional[Expression]]: 54 """ 55 Parses the given SQL string into a collection of syntax trees, one per parsed SQL statement. 56 57 Args: 58 sql: the SQL code string to parse. 59 read: the SQL dialect to apply during parsing (eg. "spark", "hive", "presto", "mysql"). 60 **opts: other `sqlglot.parser.Parser` options. 61 62 Returns: 63 The resulting syntax tree collection. 64 """ 65 dialect = Dialect.get_or_raise(read)() 66 return dialect.parse(sql, **opts)
Parses the given SQL string into a collection of syntax trees, one per parsed SQL statement.
Arguments:
- sql: the SQL code string to parse.
- read: the SQL dialect to apply during parsing (eg. "spark", "hive", "presto", "mysql").
- **opts: other
sqlglot.parser.Parser
options.
Returns:
The resulting syntax tree collection.
117def parse_one( 118 sql: str, 119 read: DialectType = None, 120 into: t.Optional[exp.IntoType] = None, 121 **opts, 122) -> Expression: 123 """ 124 Parses the given SQL string and returns a syntax tree for the first parsed SQL statement. 125 126 Args: 127 sql: the SQL code string to parse. 128 read: the SQL dialect to apply during parsing (eg. "spark", "hive", "presto", "mysql"). 129 into: the SQLGlot Expression to parse into. 130 **opts: other `sqlglot.parser.Parser` options. 131 132 Returns: 133 The syntax tree for the first parsed statement. 134 """ 135 136 dialect = Dialect.get_or_raise(read)() 137 138 if into: 139 result = dialect.parse_into(into, sql, **opts) 140 else: 141 result = dialect.parse(sql, **opts) 142 143 for expression in result: 144 if not expression: 145 raise ParseError(f"No expression was parsed from '{sql}'") 146 return expression 147 else: 148 raise ParseError(f"No expression was parsed from '{sql}'")
Parses the given SQL string and returns a syntax tree for the first parsed SQL statement.
Arguments:
- sql: the SQL code string to parse.
- read: the SQL dialect to apply during parsing (eg. "spark", "hive", "presto", "mysql").
- into: the SQLGlot Expression to parse into.
- **opts: other
sqlglot.parser.Parser
options.
Returns:
The syntax tree for the first parsed statement.
151def transpile( 152 sql: str, 153 read: DialectType = None, 154 write: DialectType = None, 155 identity: bool = True, 156 error_level: t.Optional[ErrorLevel] = None, 157 **opts, 158) -> t.List[str]: 159 """ 160 Parses the given SQL string in accordance with the source dialect and returns a list of SQL strings transformed 161 to conform to the target dialect. Each string in the returned list represents a single transformed SQL statement. 162 163 Args: 164 sql: the SQL code string to transpile. 165 read: the source dialect used to parse the input string (eg. "spark", "hive", "presto", "mysql"). 166 write: the target dialect into which the input should be transformed (eg. "spark", "hive", "presto", "mysql"). 167 identity: if set to `True` and if the target dialect is not specified the source dialect will be used as both: 168 the source and the target dialect. 169 error_level: the desired error level of the parser. 170 **opts: other `sqlglot.generator.Generator` options. 171 172 Returns: 173 The list of transpiled SQL statements. 174 """ 175 write = write or read if identity else write 176 return [ 177 Dialect.get_or_raise(write)().generate(expression, **opts) 178 for expression in parse(sql, read, error_level=error_level) 179 ]
Parses the given SQL string in accordance with the source dialect and returns a list of SQL strings transformed to conform to the target dialect. Each string in the returned list represents a single transformed SQL statement.
Arguments:
- sql: the SQL code string to transpile.
- read: the source dialect used to parse the input string (eg. "spark", "hive", "presto", "mysql").
- write: the target dialect into which the input should be transformed (eg. "spark", "hive", "presto", "mysql").
- identity: if set to
True
and if the target dialect is not specified the source dialect will be used as both: the source and the target dialect. - error_level: the desired error level of the parser.
- **opts: other
sqlglot.generator.Generator
options.
Returns:
The list of transpiled SQL statements.