Skip to main content

An easily customizable SQL parser and transpiler

Project description

SQLGlot

SQLGlot is a no dependency Python SQL parser and transpiler. It can be used to format SQL or translate between different dialects like Presto, Spark, and Hive. It aims to read a wide variety of SQL inputs and output syntatically correct SQL in the targeted dialects.

It is currently the fastest pure-Python SQL parser.

You can easily customize the parser to support UDF's across dialects as well through the transform API.

Syntax errors are highlighted and dialect incompatibilities can warn or raise depending on configurations.

Install

From PyPI

pip3 install sqlglot

Or with a local checkout

pip3 install -e .

Examples

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')
SELECT TO_UTC_TIMESTAMP(FROM_UNIXTIME(1618088028295 / 1000, 'yyyy-MM-dd HH:mm:ss'), 'UTC')

SQLGlot can even translate custom time formats.

import sqlglot
sqlglot.transpile("SELECT STRFTIME(x, '%y-%-m-%S')", read='duckdb', write='hive')
SELECT DATE_FORMAT(x, 'yy-M-ss')"

Formatting and Transpiling

Read in a SQL statement with a CTE and CASTING to a REAL and then transpiling to Spark.

Spark uses backticks as identifiers and the REAL type is transpiled to FLOAT.

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"""
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`

Customization

Custom Types

A simple transform on types can be accomplished by providing a corresponding mapping:

from sqlglot import *
from sqlglot import expressions as exp

transpile("SELECT CAST(a AS INT) FROM x", type_mapping={exp.DataType.Type.INT: "SPECIAL INT"})[0]
SELECT CAST(a AS SPECIAL INT) FROM x

More complicated transforms can be accomplished by using the Tokenizer, Parser, and Generator directly.

Custom Functions

In this example, we want to parse a UDF SPECIAL_UDF and then output another version called SPECIAL_UDF_INVERSE with the arguments switched.

from sqlglot import *
from sqlglot.expressions import Func

class SpecialUdf(Func):
    arg_types = {'a': True, 'b': True}

tokens = Tokenizer().tokenize("SELECT SPECIAL_UDF(a, b) FROM x")

Here is the output of the tokenizer:

[
    <Token token_type: TokenType.SELECT, text: SELECT, line: 0, col: 0>,
    <Token token_type: TokenType.VAR, text: SPECIAL_UDF, line: 0, col: 7>,
    <Token token_type: TokenType.L_PAREN, text: (, line: 0, col: 18>,
    <Token token_type: TokenType.VAR, text: a, line: 0, col: 19>,
    <Token token_type: TokenType.COMMA, text: ,, line: 0, col: 20>,
    <Token token_type: TokenType.VAR, text: b, line: 0, col: 22>,
    <Token token_type: TokenType.R_PAREN, text: ), line: 0, col: 23>,
    <Token token_type: TokenType.FROM, text: FROM, line: 0, col: 25>,
    <Token token_type: TokenType.VAR, text: x, line: 0, col: 30>,
]

expression = Parser(functions={
    **SpecialUdf.default_parser_mappings(),
}).parse(tokens)[0]

The expression tree produced by the parser:

(SELECT distinct: False, expressions:
  (SPECIALUDF a:
    (COLUMN this:
      (IDENTIFIER this: a, quoted: False)), b:
    (COLUMN this:
      (IDENTIFIER this: b, quoted: False))), from:
  (FROM expressions:
    (TABLE this:
      (IDENTIFIER this: x, quoted: False))))

Finally generating the new SQL:

Generator(transforms={
    SpecialUdf: lambda self, e: f"SPECIAL_UDF_INVERSE({self.sql(e, 'b')}, {self.sql(e, 'a')})"
}).generate(expression)
SELECT SPECIAL_UDF_INVERSE(b, a) FROM x

Parser Errors

A syntax error will result in a parser error.

transpile("SELECT foo( FROM bar")
sqlglot.errors.ParseError: Expected )
  SELECT foo( __FROM__ bar

Unsupported Errors

Presto APPROX_DISTINCT supports the accuracy argument which is not supported in Spark.

transpile(
    'SELECT APPROX_DISTINCT(a, 0.1) FROM foo',
    read='presto',
    write='spark',
)
WARNING:root: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()

Which outputs:

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()

Which outputs:

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:

import sqlglot
import sqlglot.expressions as exp

expression_tree = sqlglot.parse_one("SELECT a FROM x")

def transformer(node):
    if isinstance(node, exp.Column) and node.text("this") == "a":
        return sqlglot.parse_one("FUN(a)")
    return node

transformed_tree = expression_tree.transform(transformer)
transformed_tree.sql()

Which outputs:

SELECT FUN(a) FROM x

SQL Annotations

SQLGlot supports annotations in the sql expression. This is an experimental feature that is not part of any of the SQL standards but it can be useful when needing to annotate what a selected field is supposed to be. Below is an example:

SELECT
  user #primary_key,
  country
FROM users

Benchmarks

Benchmarks run on Python 3.9.6 in seconds.

Query sqlglot sqlparse moz_sql_parser sqloxide
short 0.00038 0.00104 0.00174 0.000060
long 0.00508 0.01522 0.02162 0.000597
crazy 0.01871 3.49415 0.35346 0.003104

Run Tests and Lint

python -m unittest && python -m pylint sqlglot/ tests/

Project details


Release history Release notifications | RSS feed

Download files

Download the file for your platform. If you're not sure which to choose, learn more about installing packages.

Source Distribution

sqlglot-2.3.0.tar.gz (45.2 kB view details)

Uploaded Source

Built Distribution

sqlglot-2.3.0-py3-none-any.whl (45.6 kB view details)

Uploaded Python 3

File details

Details for the file sqlglot-2.3.0.tar.gz.

File metadata

  • Download URL: sqlglot-2.3.0.tar.gz
  • Upload date:
  • Size: 45.2 kB
  • Tags: Source
  • Uploaded using Trusted Publishing? No
  • Uploaded via: twine/4.0.0 CPython/3.9.12

File hashes

Hashes for sqlglot-2.3.0.tar.gz
Algorithm Hash digest
SHA256 cdf4035b5fc5ebdd3ef95a68eec36fbc817136f616568cf18fdeeb6e0a5058fe
MD5 d8f1f75b9f288938dcbfc8e112e59df5
BLAKE2b-256 618fb4a1cb4b9d5054e77f85845d465c8ea329c26885dbbb836686345514d262

See more details on using hashes here.

Provenance

File details

Details for the file sqlglot-2.3.0-py3-none-any.whl.

File metadata

  • Download URL: sqlglot-2.3.0-py3-none-any.whl
  • Upload date:
  • Size: 45.6 kB
  • Tags: Python 3
  • Uploaded using Trusted Publishing? No
  • Uploaded via: twine/4.0.0 CPython/3.9.12

File hashes

Hashes for sqlglot-2.3.0-py3-none-any.whl
Algorithm Hash digest
SHA256 293d70858056551d8e27bb4020b76507549da28668f5fb48e7d8ba1b2f1228be
MD5 287506a445d6acdfed19654633939188
BLAKE2b-256 1c6c216a4fe0f45e62334aeee0e699fe897b0b1e4d79097a8fdd16ec378a753b

See more details on using hashes here.

Provenance

Supported by

AWS AWS Cloud computing and Security Sponsor Datadog Datadog Monitoring Fastly Fastly CDN Google Google Download Analytics Microsoft Microsoft PSF Sponsor Pingdom Pingdom Monitoring Sentry Sentry Error logging StatusPage StatusPage Status page