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.dialect import Dialect as Dialect, Dialects as Dialects 13from sqlglot.diff import diff as diff 14from sqlglot.errors import ( 15 ErrorLevel as ErrorLevel, 16 ParseError as ParseError, 17 TokenError as TokenError, 18 UnsupportedError as UnsupportedError, 19) 20from sqlglot.expressions import ( 21 Expression as Expression, 22 alias_ as alias, 23 and_ as and_, 24 column as column, 25 condition as condition, 26 except_ as except_, 27 from_ as from_, 28 intersect as intersect, 29 maybe_parse as maybe_parse, 30 not_ as not_, 31 or_ as or_, 32 select as select, 33 subquery as subquery, 34 table_ as table, 35 to_column as to_column, 36 to_table as to_table, 37 union as union, 38) 39from sqlglot.generator import Generator as Generator 40from sqlglot.parser import Parser as Parser 41from sqlglot.schema import MappingSchema as MappingSchema, Schema as Schema 42from sqlglot.tokens import Tokenizer as Tokenizer, TokenType as TokenType 43 44if t.TYPE_CHECKING: 45 from sqlglot.dialects.dialect import DialectType as DialectType 46 47 T = t.TypeVar("T", bound=Expression) 48 49 50__version__ = "11.6.3" 51 52pretty = False 53"""Whether to format generated SQL by default.""" 54 55schema = MappingSchema() 56"""The default schema used by SQLGlot (e.g. in the optimizer).""" 57 58 59def parse(sql: str, read: DialectType = None, **opts) -> t.List[t.Optional[Expression]]: 60 """ 61 Parses the given SQL string into a collection of syntax trees, one per parsed SQL statement. 62 63 Args: 64 sql: the SQL code string to parse. 65 read: the SQL dialect to apply during parsing (eg. "spark", "hive", "presto", "mysql"). 66 **opts: other `sqlglot.parser.Parser` options. 67 68 Returns: 69 The resulting syntax tree collection. 70 """ 71 dialect = Dialect.get_or_raise(read)() 72 return dialect.parse(sql, **opts) 73 74 75@t.overload 76def parse_one( 77 sql: str, 78 read: None = None, 79 into: t.Type[T] = ..., 80 **opts, 81) -> T: 82 ... 83 84 85@t.overload 86def parse_one( 87 sql: str, 88 read: DialectType, 89 into: t.Type[T], 90 **opts, 91) -> T: 92 ... 93 94 95@t.overload 96def parse_one( 97 sql: str, 98 read: None = None, 99 into: t.Union[str, t.Collection[t.Union[str, t.Type[Expression]]]] = ..., 100 **opts, 101) -> Expression: 102 ... 103 104 105@t.overload 106def parse_one( 107 sql: str, 108 read: DialectType, 109 into: t.Union[str, t.Collection[t.Union[str, t.Type[Expression]]]], 110 **opts, 111) -> Expression: 112 ... 113 114 115@t.overload 116def parse_one( 117 sql: str, 118 **opts, 119) -> Expression: 120 ... 121 122 123def parse_one( 124 sql: str, 125 read: DialectType = None, 126 into: t.Optional[exp.IntoType] = None, 127 **opts, 128) -> Expression: 129 """ 130 Parses the given SQL string and returns a syntax tree for the first parsed SQL statement. 131 132 Args: 133 sql: the SQL code string to parse. 134 read: the SQL dialect to apply during parsing (eg. "spark", "hive", "presto", "mysql"). 135 into: the SQLGlot Expression to parse into. 136 **opts: other `sqlglot.parser.Parser` options. 137 138 Returns: 139 The syntax tree for the first parsed statement. 140 """ 141 142 dialect = Dialect.get_or_raise(read)() 143 144 if into: 145 result = dialect.parse_into(into, sql, **opts) 146 else: 147 result = dialect.parse(sql, **opts) 148 149 for expression in result: 150 if not expression: 151 raise ParseError(f"No expression was parsed from '{sql}'") 152 return expression 153 else: 154 raise ParseError(f"No expression was parsed from '{sql}'") 155 156 157def transpile( 158 sql: str, 159 read: DialectType = None, 160 write: DialectType = None, 161 identity: bool = True, 162 error_level: t.Optional[ErrorLevel] = None, 163 **opts, 164) -> t.List[str]: 165 """ 166 Parses the given SQL string in accordance with the source dialect and returns a list of SQL strings transformed 167 to conform to the target dialect. Each string in the returned list represents a single transformed SQL statement. 168 169 Args: 170 sql: the SQL code string to transpile. 171 read: the source dialect used to parse the input string (eg. "spark", "hive", "presto", "mysql"). 172 write: the target dialect into which the input should be transformed (eg. "spark", "hive", "presto", "mysql"). 173 identity: if set to `True` and if the target dialect is not specified the source dialect will be used as both: 174 the source and the target dialect. 175 error_level: the desired error level of the parser. 176 **opts: other `sqlglot.generator.Generator` options. 177 178 Returns: 179 The list of transpiled SQL statements. 180 """ 181 write = write or read if identity else write 182 return [ 183 Dialect.get_or_raise(write)().generate(expression, **opts) 184 for expression in parse(sql, read, error_level=error_level) 185 ]
Whether to format generated SQL by default.
The default schema used by SQLGlot (e.g. in the optimizer).
60def parse(sql: str, read: DialectType = None, **opts) -> t.List[t.Optional[Expression]]: 61 """ 62 Parses the given SQL string into a collection of syntax trees, one per parsed SQL statement. 63 64 Args: 65 sql: the SQL code string to parse. 66 read: the SQL dialect to apply during parsing (eg. "spark", "hive", "presto", "mysql"). 67 **opts: other `sqlglot.parser.Parser` options. 68 69 Returns: 70 The resulting syntax tree collection. 71 """ 72 dialect = Dialect.get_or_raise(read)() 73 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.
124def parse_one( 125 sql: str, 126 read: DialectType = None, 127 into: t.Optional[exp.IntoType] = None, 128 **opts, 129) -> Expression: 130 """ 131 Parses the given SQL string and returns a syntax tree for the first parsed SQL statement. 132 133 Args: 134 sql: the SQL code string to parse. 135 read: the SQL dialect to apply during parsing (eg. "spark", "hive", "presto", "mysql"). 136 into: the SQLGlot Expression to parse into. 137 **opts: other `sqlglot.parser.Parser` options. 138 139 Returns: 140 The syntax tree for the first parsed statement. 141 """ 142 143 dialect = Dialect.get_or_raise(read)() 144 145 if into: 146 result = dialect.parse_into(into, sql, **opts) 147 else: 148 result = dialect.parse(sql, **opts) 149 150 for expression in result: 151 if not expression: 152 raise ParseError(f"No expression was parsed from '{sql}'") 153 return expression 154 else: 155 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.
158def transpile( 159 sql: str, 160 read: DialectType = None, 161 write: DialectType = None, 162 identity: bool = True, 163 error_level: t.Optional[ErrorLevel] = None, 164 **opts, 165) -> t.List[str]: 166 """ 167 Parses the given SQL string in accordance with the source dialect and returns a list of SQL strings transformed 168 to conform to the target dialect. Each string in the returned list represents a single transformed SQL statement. 169 170 Args: 171 sql: the SQL code string to transpile. 172 read: the source dialect used to parse the input string (eg. "spark", "hive", "presto", "mysql"). 173 write: the target dialect into which the input should be transformed (eg. "spark", "hive", "presto", "mysql"). 174 identity: if set to `True` and if the target dialect is not specified the source dialect will be used as both: 175 the source and the target dialect. 176 error_level: the desired error level of the parser. 177 **opts: other `sqlglot.generator.Generator` options. 178 179 Returns: 180 The list of transpiled SQL statements. 181 """ 182 write = write or read if identity else write 183 return [ 184 Dialect.get_or_raise(write)().generate(expression, **opts) 185 for expression in parse(sql, read, error_level=error_level) 186 ]
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.