This Ruby extension uses the actual PostgreSQL server source to parse SQL queries and return the internal PostgreSQL parsetree.
In addition the extension allows you to normalize queries (replacing constant values with ?) and parse these normalized queries into a parsetree again.
When you build this extension, it builds parts of the PostgreSQL server source (see libpg_query), and then statically links it into this extension.
This is slightly crazy, but is the only reliable way of parsing all valid PostgreSQL queries.
You can find further examples and a longer rationale here: https://pganalyze.com/blog/parse-postgresql-queries-in-ruby.html
gem install pg_query
Due to compiling parts of PostgreSQL, installation might take a while on slower systems. Expect up to 5 minutes.
PgQuery.parse("SELECT 1")
=> #<PgQuery::ParserResult:0x00007fb69a958820
@query="SELECT 1",
@tree=<PgQuery::ParseResult:
version: 130002,
stmts: [
<PgQuery::RawStmt:
stmt: <PgQuery::Node:
select_stmt: <PgQuery::SelectStmt:
distinct_clause: [],
target_list: [
<PgQuery::Node:
res_target: <PgQuery::ResTarget:
name: "",
indirection: [],
val: <PgQuery::Node:
a_const: <PgQuery::A_Const:
val: <PgQuery::Node:
integer: <PgQuery::Integer: ival: 1>
>,
location: 7
>
>,
location: 7
>
>
],
from_clause: [],
group_clause: [],
window_clause: [],
values_lists: [],
sort_clause: [],
limit_option: :LIMIT_OPTION_DEFAULT,
locking_clause: [],
op: :SETOP_NONE,
all: false
>
>,
stmt_location: 0,
stmt_len: 0
>
]
>,
@warnings=[]>
parsed_query = PgQuery.parse("SELECT * FROM users")
# Modify the parse tree in some way
parsed_query.tree.stmts[0].stmt.select_stmt.from_clause[0].range_var.relname = 'other_users'
# Turn it into SQL again
parsed_query.deparse
=> "SELECT * FROM other_users"
# Normalizing a query (like pg_stat_statements in Postgres 10+)
PgQuery.normalize("SELECT 1 FROM x WHERE y = 'foo'")
=> "SELECT $1 FROM x WHERE y = $2"
# Parsing a normalized query (pre-Postgres 10 style)
PgQuery.parse("SELECT ? FROM x WHERE y = ?")
=> #<PgQuery::ParserResult:0x00007fb69a97a5d8
@query="SELECT ? FROM x WHERE y = ?",
@tree=<PgQuery::ParseResult: ...>,
@warnings=[]>
PgQuery.parse("SELECT ? FROM x JOIN y USING (id) WHERE z = ?").tables
=> ["x", "y"]
PgQuery.parse("SELECT ? FROM x WHERE x.y = ? AND z = ?").filter_columns
=> [["x", "y"], [nil, "z"]]
PgQuery.parse("SELECT 1").fingerprint
=> "50fde20626009aba"
PgQuery.parse("SELECT 2; --- comment").fingerprint
=> "50fde20626009aba"
# Faster fingerprint method that is implemented inside the native C library
PgQuery.fingerprint("SELECT ?")
=> "50fde20626009aba"
PgQuery.scan('SELECT 1 --comment')
=> [<PgQuery::ScanResult: version: 130002, tokens: [
<PgQuery::ScanToken: start: 0, end: 6, token: :SELECT, keyword_kind: :RESERVED_KEYWORD>,
<PgQuery::ScanToken: start: 7, end: 8, token: :ICONST, keyword_kind: :NO_KEYWORD>,
<PgQuery::ScanToken: start: 9, end: 18, token: :SQL_COMMENT, keyword_kind: :NO_KEYWORD>]>,
[]]
This gem is based on libpg_query,
which uses the latest stable PostgreSQL version, but with a patch applied
to support parsing normalized queries containing ?
replacement characters.
Currently tested and officially supported Ruby versions:
- CRuby 2.5
- CRuby 2.6
- CRuby 2.7
- CRuby 3.0
Not supported:
- JRuby:
pg_query
relies on a C extension, which is discouraged / not properly supported for JRuby - TruffleRuby: GraalVM does not support sigjmp, which is used by the Postgres error handling code (
pg_query
uses a copy of the Postgres parser & error handling code)
In order to update to a newer Postgres parser, first update libpg_query to the new Postgres version and tag a release.
Once that is done, follow the following steps:
-
Update
LIB_PG_QUERY_TAG
andLIB_PG_QUERY_SHA256SUM
inRakefile
-
Run
rake update_source
to update the source code -
Commit the
Rakefile
and the modified files inext/pg_query
to this source tree and make a PR
See libpg_query for pg_query in other languages, as well as products/tools built on pg_query.
- Jack Danger Canty, for significantly improving deparsing
Copyright (c) 2015, pganalyze Team [email protected]
pg_query is licensed under the 3-clause BSD license, see LICENSE file for details.
Query normalization code:
Copyright (c) 2008-2015, PostgreSQL Global Development Group