Merge remote-tracking branch 'master' into ruby_param_validation
This commit is contained in:
commit
bf60b105e1
10 changed files with 1143 additions and 9 deletions
2
Gemfile
2
Gemfile
|
@ -42,7 +42,7 @@ gem 'font_assets', '~> 0.1.14'
|
|||
|
||||
# Database (postgres)
|
||||
gem 'pg' # Postgresql
|
||||
gem 'qx', git: 'https://github.com/commitchange/ruby-qx.git'
|
||||
gem 'qx', path: 'gems/ruby-qx'
|
||||
gem 'dalli'
|
||||
gem 'memcachier'
|
||||
|
||||
|
|
16
Gemfile.lock
16
Gemfile.lock
|
@ -1,11 +1,3 @@
|
|||
GIT
|
||||
remote: https://github.com/commitchange/ruby-qx.git
|
||||
revision: 3c7fbb9c844e3ea86c9faea204058aa76e5ea35d
|
||||
specs:
|
||||
qx (0.1.1)
|
||||
activerecord (>= 3.0)
|
||||
colorize (~> 0.8)
|
||||
|
||||
GIT
|
||||
remote: https://github.com/commitchange/stripe-ruby-mock.git
|
||||
revision: ee4471a8f654672d5596218c2b68a2913ea3f4cc
|
||||
|
@ -40,6 +32,14 @@ PATH
|
|||
param_validation (0.0.2)
|
||||
chronic
|
||||
|
||||
PATH
|
||||
remote: gems/ruby-qx
|
||||
specs:
|
||||
qx (0.1.1)
|
||||
activerecord (>= 3.0)
|
||||
colorize (~> 0.8)
|
||||
|
||||
|
||||
GEM
|
||||
remote: https://rubygems.org/
|
||||
specs:
|
||||
|
|
8
gems/COPYING
Normal file
8
gems/COPYING
Normal file
|
@ -0,0 +1,8 @@
|
|||
Copyright 2015 Jay R Bolton
|
||||
Copyright 2017 CommitChange
|
||||
|
||||
Permission is hereby granted, free of charge, to any person obtaining a copy of this software and associated documentation files (the "Software"), to deal in the Software without restriction, including without limitation the rights to use, copy, modify, merge, publish, distribute, sublicense, and/or sell copies of the Software, and to permit persons to whom the Software is furnished to do so, subject to the following conditions:
|
||||
|
||||
The above copyright notice and this permission notice shall be included in all copies or substantial portions of the Software.
|
||||
|
||||
THE SOFTWARE IS PROVIDED "AS IS", WITHOUT WARRANTY OF ANY KIND, EXPRESS OR IMPLIED, INCLUDING BUT NOT LIMITED TO THE WARRANTIES OF MERCHANTABILITY, FITNESS FOR A PARTICULAR PURPOSE AND NONINFRINGEMENT. IN NO EVENT SHALL THE AUTHORS OR COPYRIGHT HOLDERS BE LIABLE FOR ANY CLAIM, DAMAGES OR OTHER LIABILITY, WHETHER IN AN ACTION OF CONTRACT, TORT OR OTHERWISE, ARISING FROM, OUT OF OR IN CONNECTION WITH THE SOFTWARE OR THE USE OR OTHER DEALINGS IN THE SOFTWARE.
|
273
gems/ruby-qx/README.md
Normal file
273
gems/ruby-qx/README.md
Normal file
|
@ -0,0 +1,273 @@
|
|||
# This library is deprecated. You can use [Arel](https://github.com/rails/arel) instead
|
||||
|
||||
# Qx
|
||||
|
||||
A ruby SQL expression builder (and executor) focused on Postgresql. It allows you to directly and safely write efficient SQL expressions in Ruby, using data from Ruby-land. These expressions can be passed around, reused, and modified. This lib is for those of us who want to use SQL directly within ruby, and do not want an ORM.
|
||||
|
||||
This library uses ActiveRecord for executing SQL, taking advantage of its connection pooling features. If you'd like to see support for Sequel, etc, please make a PR.
|
||||
|
||||
This implements a subset of the SQL language that we find most useful so far. Add new SQL clauses with a PR if you'd like to see more in here.
|
||||
|
||||
_*Example*_
|
||||
|
||||
```rb
|
||||
# A fairly complex query with subqueries inside some joins:
|
||||
# Create a select query on the payments table
|
||||
payments_subquery = Qx.select( "supporter_id", "SUM(gross_amount)", "MAX(date) AS max_date", "MIN(date) AS min_date", "COUNT(*) AS count")
|
||||
.from(:payments)
|
||||
.group_by(:supporter_id)
|
||||
.as(:payments)
|
||||
|
||||
# Another subquery
|
||||
tags_subquery = Qx.select("tag_joins.supporter_id", "ARRAY_AGG(tag_masters.id) AS ids", "ARRAY_AGG(tag_masters.name::text) AS names")
|
||||
.from(:tag_joins)
|
||||
.join(:tag_masters, "tag_masters.id=tag_joins.tag_master_id")
|
||||
.group_by("tag_joins.supporter_id")
|
||||
.as(:tags)
|
||||
|
||||
# Combine the above subqueries into a select on the supporters table
|
||||
expr = Qx.select('supporters.id').from(:supporters)
|
||||
.left_join(tags_subquery, "tags.supporter_id=supporters.id")
|
||||
.add_left_join(payments_subquery, "payments.supporter_id=supporters.id")
|
||||
.where("supporters.nonprofit_id=$id", id: np_id.to_i)
|
||||
.and_where("coalesce(supporters.deleted, FALSE) = FALSE")
|
||||
.order_by('payments.max_date DESC NULLS LAST')
|
||||
.execute(format: 'csv')
|
||||
|
||||
# Easy bulk insert
|
||||
Qx.insert_into(:table_name).values([{x: 1}, {x: 2}, {x: 3}]).execute
|
||||
# Qx also supports insert from selects, like `INSERT INTO x (y) SELECT y FROM x`
|
||||
Qx.insert_into(:table_name, ['x']).select("x").from("table2").execute
|
||||
```
|
||||
|
||||
# Qx.config(options)
|
||||
|
||||
`Qx.config` takes a hash of options. For now, there is only one option: `:type_map`, which allows you to specify a PG typemap
|
||||
|
||||
```
|
||||
Qx.config(type_map: PG::BasicTypeMapForResults.new(ActiveRecord::Base.connection.raw_connection))
|
||||
```
|
||||
|
||||
`.config` is best called in an initializer when your app is starting up. Be sure to initialize ActiveRecord before using Qx. In Rails, you don't need to do anything extra for that.
|
||||
|
||||
# API
|
||||
|
||||
Please refer to this test file to see all the SQL constructor methods: [/test/qx_test.rb](/test/qx_test.rb)
|
||||
|
||||
For each test, see the `assert_equal` line to find the resulting SQL expression. Above that, in the `parsed = ...` line, you can see how the expression was created using Qx.
|
||||
|
||||
## `expression.execute`
|
||||
|
||||
When you have an expression, call `.execute` to actually execute it.
|
||||
|
||||
```rb
|
||||
Qx.select("id", "name").from(:users).where(email: "user@example.com").execute
|
||||
```
|
||||
|
||||
`.ex` is a shortcut alias
|
||||
|
||||
## `Qx.execute_file(path, interpolation_data, options)`
|
||||
|
||||
This function will open a sql file and execute its contents. You can interpolate data into the file with `$variable_name`.
|
||||
|
||||
Given a sql file like:
|
||||
|
||||
```sql
|
||||
SELECT * FROM users WHERE account_id=$account_id LIMIT 1
|
||||
```
|
||||
|
||||
You can execute the file with:
|
||||
|
||||
```rb
|
||||
Qx.execute_file('./get_user.sql', account_id: 123)
|
||||
# -> [{email: 'uzr@example.com', ...}]
|
||||
```
|
||||
|
||||
## `.parse`
|
||||
|
||||
Instead of executing the expression, you can parse the expression into a string:
|
||||
|
||||
```rb
|
||||
Qx.select("id", "name").from(:users).where(email: "user@example.com").parse
|
||||
# -> "SELECT id, name FROM users WHERE email = 'user@example.com'"
|
||||
```
|
||||
|
||||
Note you can also use `.pp` to pretty-print the expression for debugging (for now it just colorizes, but in the near future it will indent the expression for you)
|
||||
|
||||
## shortcut / helper functions
|
||||
|
||||
Some convenience functions are provided that compose SQL expressions for you.
|
||||
|
||||
### Qx.fetch(table_name, ids_or_data)
|
||||
|
||||
This is a quick way to fetch some full rows of data by id or another column. You can either pass in an array of ids, a single id, or a hash that matches on columns.
|
||||
|
||||
```rb
|
||||
Qx.fetch(:table_name, [12, 34, 56])
|
||||
# SELECT * FROM table_name WHERE ids IN (12, 34, 56)
|
||||
|
||||
donation = Qx.fetch(:donations, 23)
|
||||
# SELECT * FROM donations WHERE ID IN (23)
|
||||
donor = Qx.fetch(:donors, donation['supporter_id'])
|
||||
# SELECT * FROM donors WHERE ID IN (33)
|
||||
|
||||
# Select by a different column besides "id" -- in this case, we use "status"
|
||||
donation = Qx.fetch(:donations, {status: 'active'})
|
||||
# SELECT * FROM donations WHERE status IN ('active')
|
||||
```
|
||||
|
||||
### expr.common_values(hash)
|
||||
|
||||
If you're bulk inserting but want some common values in all your rows, you
|
||||
don't have to have that common data in every single row. Instead, you can use
|
||||
`.common_values`:
|
||||
|
||||
```rb
|
||||
expr = Qx.insert_into(:table_name)
|
||||
.values([{x: 1}, {x: 2}])
|
||||
.common_values({y: 'common'})
|
||||
# INSERT INTO "table_name" ("x", "y")
|
||||
# VALUES (1, 'common'), (2, 'common')
|
||||
```
|
||||
|
||||
### expr.timestamps
|
||||
|
||||
Inside an `INSERT INTO` expression, if you add the `.timestamps` method, it will add both `created_at` and `updated_at` columns, set to the current utc time.
|
||||
|
||||
```
|
||||
Qx.insert_into(:table_name).values(x: 1).timestamps.execute
|
||||
# INSERT INTO table_name (x, created_at, updated_at) VALUES (1, '2020-01-01 00:00:00 UTC', '2020-01-01 00:00:00 UTC')
|
||||
# (pretending that the above dates is Time.now)
|
||||
```
|
||||
|
||||
Inside an `UPDATE` expression, `.timestamps` will set the `updated_at` column to the current time for you:
|
||||
|
||||
```
|
||||
Qx.update(:table_name).set(x: 1).timestamps.where(id: 1).execute
|
||||
# UPDATE table_name SET x=1, updated_at='2020-01-01 00:00:00 UTC' WHERE id=1
|
||||
```
|
||||
|
||||
`.ts` is a shortcut alias for this method
|
||||
|
||||
## expr.pp (pretty-printing)
|
||||
|
||||
This gives a nicely formatted and colorized output of your expression for debugging.
|
||||
|
||||
```rb
|
||||
Qx.select(:id)
|
||||
.from(:table)
|
||||
.where("id IN ($ids)", ids: [1,2,3,4])
|
||||
.pp
|
||||
```
|
||||
|
||||
For now it just adds some syntax highlighting; in the near future it will also add indentation.
|
||||
|
||||
## expr.paginate(current_page, page_length)
|
||||
|
||||
This is a convenience method for more easily paginating a SELECT query using the combination of OFFSET and LIMIT
|
||||
|
||||
Simply pass in the page length and the current page to get the paginated results.
|
||||
|
||||
```rb
|
||||
Qx.select(:id).from(:table).paginate(2, 30)
|
||||
# SELECT id FROM table OFFSET 30 LIMIT 30
|
||||
```
|
||||
|
||||
## JSON helpers
|
||||
|
||||
A helper method, called `.to_json(alias)` allows you to wrap your results in a json blob. Under the hood it composes the postgres functions `array_to_json(array_agg(row_to_json(t)))` to conveniently convert a collection of sql data into a single json blob.
|
||||
|
||||
Notice in this example that there is one result with one key called "data", mapped to a single JSON string:
|
||||
|
||||
```
|
||||
Qx.select(:id, :email).from(:users).to_json(:data).execute
|
||||
# SELECT row_to_json(data) AS data FROM (SELECT id, email FROM users) data
|
||||
# returns [
|
||||
# { "data" => "[{\"id\": 1, \"email\": \"bob@example.com\"}, {\"id\": 1, \"email\": \"bob@example.com\"}]" }
|
||||
# ]
|
||||
```
|
||||
|
||||
In doing highly nested json, you can call `.to_json(alias)` within different subqueries. This example borrows from a JSON API (jsonapi.org) example:
|
||||
|
||||
```rb
|
||||
definitions = Qx.select(:part_of_speech, :body)
|
||||
.from("definitions")
|
||||
.where("word_id=words.id")
|
||||
.order_by("position ASC")
|
||||
.to_json("ds")
|
||||
|
||||
expr = Qx.select(:text, :pronunciation, definitions.as("definitions"))
|
||||
.from("words")
|
||||
.where("text='autumn'")
|
||||
.to_json("data")
|
||||
```
|
||||
|
||||
The above nested expression parses into the following sql:
|
||||
|
||||
```sql
|
||||
SELECT array_to_json(array_agg(row_to_json(data))) AS data
|
||||
FROM (
|
||||
SELECT
|
||||
text
|
||||
, pronunciation
|
||||
, (
|
||||
SELECT array_to_json(array_agg(row_to_json(d)))
|
||||
FROM (
|
||||
SELECT part_of_speech, body
|
||||
FROM definitions
|
||||
WHERE word_id=words.id
|
||||
ORDER BY position asc
|
||||
) d
|
||||
) AS definitions
|
||||
FROM words
|
||||
WHERE text = 'autumn'
|
||||
) data
|
||||
```
|
||||
|
||||
And, when executed, will give the following json string:
|
||||
|
||||
```json
|
||||
{
|
||||
"text": "autumn",
|
||||
"pronunciation": "autumn",
|
||||
"definitions": [
|
||||
{
|
||||
"part_of_speech": "noun",
|
||||
"body": "skilder wearifully uninfolded..."
|
||||
},
|
||||
{
|
||||
"part_of_speech": "verb",
|
||||
"body": "intrafissural fernbird kittly..."
|
||||
},
|
||||
{
|
||||
"part_of_speech": "adverb",
|
||||
"body": "infrugal lansquenet impolarizable..."
|
||||
}
|
||||
]
|
||||
}
|
||||
```
|
||||
|
||||
## Performance Optimization Tools
|
||||
|
||||
Since this lib is built with Postgresql, it takes advantage of its performance optimization tools such as EXPLAIN, ANALYZE, and statistics queries.
|
||||
|
||||
### expr.explain
|
||||
|
||||
For performance optimization, you can use an `EXPLAIN` command on a Qx select expression object (http://www.postgresql.org/docs/9.5/static/using-explain.html).
|
||||
|
||||
```rb
|
||||
Qx.select(:id)
|
||||
.from(:table)
|
||||
.where("id IN ($ids)", ids: [1,2,3,4])
|
||||
.explain
|
||||
.execute
|
||||
```
|
||||
|
||||
|
||||
## Development and testing
|
||||
|
||||
#### Testing
|
||||
|
||||
Set up Postgres on your machine and create a database called `qx_test`. Grant all privileges to a user called `admin` with password `password`
|
||||
|
||||
Run tests with `ruby test/qx_test.rb`
|
529
gems/ruby-qx/lib/qx.rb
Normal file
529
gems/ruby-qx/lib/qx.rb
Normal file
|
@ -0,0 +1,529 @@
|
|||
require 'active_record'
|
||||
require 'colorize'
|
||||
|
||||
class Qx
|
||||
##
|
||||
# Initialize the database connection using a database url
|
||||
# Running this is required for #execute to work
|
||||
# Pass in a hash. For now, it only takes on key called :database_url
|
||||
# Include the full url including userpass and database name
|
||||
# For example:
|
||||
# Qx.config(database_url: 'postgres://admin:password@localhost/database_name')
|
||||
@@type_map = nil
|
||||
def self.config(h)
|
||||
@@type_map = h[:type_map]
|
||||
end
|
||||
|
||||
# Qx.new, only used internally
|
||||
def initialize(tree)
|
||||
@tree = tree
|
||||
self
|
||||
end
|
||||
|
||||
def self.transaction(&block)
|
||||
ActiveRecord::Base.transaction do
|
||||
yield block
|
||||
end
|
||||
end
|
||||
|
||||
def self.parse_select(expr)
|
||||
str = 'SELECT'
|
||||
if expr[:DISTINCT_ON]
|
||||
str += " DISTINCT ON (#{expr[:DISTINCT_ON].map(&:to_s).join(', ')})"
|
||||
elsif expr[:DISTINCT]
|
||||
str += ' DISTINCT'
|
||||
end
|
||||
str += ' ' + expr[:SELECT].map { |expr| expr.is_a?(Qx) ? expr.parse : expr }.join(', ')
|
||||
throw ArgumentError.new('FROM clause is missing for SELECT') unless expr[:FROM]
|
||||
str += ' FROM ' + expr[:FROM]
|
||||
str += expr[:JOIN].map { |from, cond| " JOIN #{from} ON #{cond}" }.join if expr[:JOIN]
|
||||
str += expr[:LEFT_JOIN].map { |from, cond| " LEFT JOIN #{from} ON #{cond}" }.join if expr[:LEFT_JOIN]
|
||||
str += expr[:LEFT_OUTER_JOIN].map { |from, cond| " LEFT OUTER JOIN #{from} ON #{cond}" }.join if expr[:LEFT_OUTER_JOIN]
|
||||
str += expr[:JOIN_LATERAL].map {|i| " JOIN LATERAL (#{i[:select_statement]}) #{i[:join_name]} ON #{i[:success_condition]}"}.join if expr[:JOIN_LATERAL]
|
||||
str += ' WHERE ' + expr[:WHERE].map { |w| "(#{w})" }.join(' AND ') if expr[:WHERE]
|
||||
str += ' GROUP BY ' + expr[:GROUP_BY].join(', ') if expr[:GROUP_BY]
|
||||
str += ' HAVING ' + expr[:HAVING].map { |h| "(#{h})" }.join(' AND ') if expr[:HAVING]
|
||||
str += ' ORDER BY ' + expr[:ORDER_BY].map { |col, order| col + (order ? ' ' + order : '') }.join(', ') if expr[:ORDER_BY]
|
||||
str += ' LIMIT ' + expr[:LIMIT] if expr[:LIMIT]
|
||||
str += ' OFFSET ' + expr[:OFFSET] if expr[:OFFSET]
|
||||
str = "(#{str}) AS #{expr[:AS]}" if expr[:AS]
|
||||
str = "EXPLAIN #{str}" if expr[:EXPLAIN]
|
||||
str
|
||||
end
|
||||
|
||||
# Parse a Qx expression tree into a single query string that can be executed
|
||||
# http://www.postgresql.org/docs/9.0/static/sql-commands.html
|
||||
def self.parse(expr)
|
||||
if expr.is_a?(String)
|
||||
return expr # already parsed
|
||||
elsif expr.is_a?(Array)
|
||||
return expr.join(',')
|
||||
elsif expr[:INSERT_INTO]
|
||||
str = "INSERT INTO #{expr[:INSERT_INTO]} (#{expr[:INSERT_COLUMNS].join(', ')})"
|
||||
throw ArgumentError.new('VALUES (or SELECT) clause is missing for INSERT INTO') unless expr[:VALUES] || expr[:SELECT]
|
||||
throw ArgumentError.new("For safety, you can't use SELECT without insert columns for an INSERT INTO") if !expr[:INSERT_COLUMNS] && expr[:SELECT]
|
||||
if expr[:SELECT]
|
||||
str += ' ' + parse_select(expr)
|
||||
else
|
||||
str += " VALUES #{expr[:VALUES].map { |vals| "(#{vals.join(', ')})" }.join(', ')}"
|
||||
end
|
||||
if expr[:ON_CONFLICT]
|
||||
str += ' ON CONFLICT'
|
||||
|
||||
if expr[:CONFLICT_COLUMNS]
|
||||
str += " (#{expr[:CONFLICT_COLUMNS].join(', ')})"
|
||||
elsif expr[:ON_CONSTRAINT]
|
||||
str += " ON CONSTRAINT #{expr[:ON_CONSTRAINT]}"
|
||||
end
|
||||
str += ' DO NOTHING' if !expr[:CONFLICT_UPSERT]
|
||||
if expr[:CONFLICT_UPSERT]
|
||||
set_str = expr[:INSERT_COLUMNS].select{|i| i != 'created_at'}.map{|i| "#{i} = EXCLUDED.#{i}" }
|
||||
str += " DO UPDATE SET #{set_str.join(', ')}"
|
||||
end
|
||||
end
|
||||
str += ' RETURNING ' + expr[:RETURNING].join(', ') if expr[:RETURNING]
|
||||
elsif expr[:SELECT]
|
||||
str = parse_select(expr)
|
||||
elsif expr[:DELETE_FROM]
|
||||
str = 'DELETE FROM ' + expr[:DELETE_FROM]
|
||||
throw ArgumentError.new('WHERE clause is missing for DELETE FROM') unless expr[:WHERE]
|
||||
str += ' WHERE ' + expr[:WHERE].map { |w| "(#{w})" }.join(' AND ')
|
||||
str += ' RETURNING ' + expr[:RETURNING].join(', ') if expr[:RETURNING]
|
||||
elsif expr[:UPDATE]
|
||||
str = 'UPDATE ' + expr[:UPDATE]
|
||||
throw ArgumentError.new('SET clause is missing for UPDATE') unless expr[:SET]
|
||||
throw ArgumentError.new('WHERE clause is missing for UPDATE') unless expr[:WHERE]
|
||||
str += ' SET ' + expr[:SET]
|
||||
str += ' FROM ' + expr[:FROM] if expr[:FROM]
|
||||
str += ' WHERE ' + expr[:WHERE].map { |w| "(#{w})" }.join(' AND ')
|
||||
str += ' ' + expr[:ON_CONFLICT] if expr[:ON_CONFLICT]
|
||||
str += ' RETURNING ' + expr[:RETURNING].join(', ') if expr[:RETURNING]
|
||||
end
|
||||
str
|
||||
end
|
||||
|
||||
# An instance method version of the above
|
||||
def parse
|
||||
Qx.parse(@tree)
|
||||
end
|
||||
|
||||
# Qx.select("id").from("supporters").execute
|
||||
def execute(options = {})
|
||||
expr = Qx.parse(@tree).to_s.encode('UTF-8', 'binary', invalid: :replace, undef: :replace, replace: '')
|
||||
Qx.execute_raw(expr, options)
|
||||
end
|
||||
alias ex execute
|
||||
|
||||
# Can pass in an expression string or another Qx object
|
||||
# Qx.execute("SELECT id FROM table_name", {format: 'csv'})
|
||||
# Qx.execute(Qx.select("id").from("table_name"))
|
||||
def self.execute(expr, data = {}, options = {})
|
||||
return expr.execute(data) if expr.is_a?(Qx)
|
||||
interpolated = Qx.interpolate_expr(expr, data)
|
||||
execute_raw(interpolated, options)
|
||||
end
|
||||
|
||||
# options
|
||||
# verbose: print the query
|
||||
# format: 'csv' | 'hash' give data csv style with Arrays -- good for exports or for saving memory
|
||||
def self.execute_raw(expr, options = {})
|
||||
puts expr if options[:verbose]
|
||||
if options[:copy_csv]
|
||||
expr = "COPY (#{expr}) TO '#{options[:copy_csv]}' DELIMITER ',' CSV HEADER"
|
||||
end
|
||||
result = ActiveRecord::Base.connection.execute(expr)
|
||||
result.map_types!(@@type_map) if @@type_map
|
||||
if options[:format] == 'csv'
|
||||
data = result.map(&:values)
|
||||
data.unshift((result.first || {}).keys)
|
||||
else
|
||||
data = result.map { |h| h }
|
||||
end
|
||||
result.clear
|
||||
data = data.map { |row| apply_nesting(row) } if options[:nesting]
|
||||
data
|
||||
end
|
||||
|
||||
def self.execute_file(path, data = {}, options = {})
|
||||
Qx.execute_raw(Qx.interpolate_expr(File.open(path, 'r').read, data), options)
|
||||
end
|
||||
|
||||
# helpers for JSON conversion
|
||||
def to_json(name)
|
||||
name = name.to_s
|
||||
Qx.select("array_to_json(array_agg(row_to_json(#{name})))").from(as(name))
|
||||
end
|
||||
|
||||
# -- Top-level clauses
|
||||
|
||||
def self.select(*cols)
|
||||
new(SELECT: cols)
|
||||
end
|
||||
|
||||
def select(*cols)
|
||||
@tree[:SELECT] = cols
|
||||
self
|
||||
end
|
||||
|
||||
def add_select(*cols)
|
||||
@tree[:SELECT].push(cols)
|
||||
self
|
||||
end
|
||||
|
||||
# @returns [Qx]
|
||||
def self.insert_into(table_name, cols = [])
|
||||
new(INSERT_INTO: Qx.quote_ident(table_name), INSERT_COLUMNS: cols.map { |c| Qx.quote_ident(c) })
|
||||
end
|
||||
|
||||
def insert_into(table_name, cols = [])
|
||||
@tree[:INSERT_INTO] = Qx.quote_ident(table_name)
|
||||
@tree[:INSERT_COLUMNS] = cols.map { |c| Qx.quote_ident(c) }
|
||||
self
|
||||
end
|
||||
|
||||
def self.delete_from(table_name)
|
||||
new(DELETE_FROM: Qx.quote_ident(table_name))
|
||||
end
|
||||
|
||||
def delete_from(table_name)
|
||||
@tree[:DELETE_FROM] = Qx.quote_ident(table_name)
|
||||
self
|
||||
end
|
||||
|
||||
def self.update(table_name)
|
||||
new(UPDATE: Qx.quote_ident(table_name))
|
||||
end
|
||||
|
||||
def update(table_name)
|
||||
@tree[:UPDATE] = Qx.quote_ident(table_name)
|
||||
self
|
||||
end
|
||||
|
||||
# -- Sub-clauses
|
||||
|
||||
# - SELECT sub-clauses
|
||||
|
||||
def distinct
|
||||
@tree[:DISTINCT] = true
|
||||
self
|
||||
end
|
||||
|
||||
def distinct_on(*cols)
|
||||
@tree[:DISTINCT_ON] = cols
|
||||
self
|
||||
end
|
||||
|
||||
def from(expr)
|
||||
@tree[:FROM] = expr.is_a?(Qx) ? expr.parse : expr.to_s
|
||||
self
|
||||
end
|
||||
|
||||
def as(table_name)
|
||||
@tree[:AS] = Qx.quote_ident(table_name)
|
||||
self
|
||||
end
|
||||
|
||||
# Clauses are pairs of expression and data
|
||||
def where(*clauses)
|
||||
ws = Qx.get_where_params(clauses)
|
||||
@tree[:WHERE] = Qx.parse_wheres(ws)
|
||||
self
|
||||
end
|
||||
|
||||
def and_where(*clauses)
|
||||
ws = Qx.get_where_params(clauses)
|
||||
@tree[:WHERE] ||= []
|
||||
@tree[:WHERE].concat(Qx.parse_wheres(ws))
|
||||
self
|
||||
end
|
||||
|
||||
def group_by(*cols)
|
||||
@tree[:GROUP_BY] = cols.map(&:to_s)
|
||||
self
|
||||
end
|
||||
|
||||
def order_by(*cols)
|
||||
orders = /(asc)|(desc)( nulls (first)|(last))?/i
|
||||
# Sanitize out invalid order keywords
|
||||
@tree[:ORDER_BY] = cols.map { |col, order| [col.to_s, order.to_s.downcase.strip.match(order.to_s.downcase) ? order.to_s.upcase : nil] }
|
||||
self
|
||||
end
|
||||
|
||||
def having(expr, data = {})
|
||||
@tree[:HAVING] = [Qx.interpolate_expr(expr, data)]
|
||||
self
|
||||
end
|
||||
|
||||
def and_having(expr, data = {})
|
||||
@tree[:HAVING].push(Qx.interpolate_expr(expr, data))
|
||||
self
|
||||
end
|
||||
|
||||
def limit(n)
|
||||
@tree[:LIMIT] = n.to_i.to_s
|
||||
self
|
||||
end
|
||||
|
||||
def offset(n)
|
||||
@tree[:OFFSET] = n.to_i.to_s
|
||||
self
|
||||
end
|
||||
|
||||
def join(*joins)
|
||||
js = Qx.get_join_param(joins)
|
||||
@tree[:JOIN] = Qx.parse_joins(js)
|
||||
self
|
||||
end
|
||||
|
||||
def add_join(*joins)
|
||||
js = Qx.get_join_param(joins)
|
||||
@tree[:JOIN] ||= []
|
||||
@tree[:JOIN].concat(Qx.parse_joins(js))
|
||||
self
|
||||
end
|
||||
|
||||
def left_join(*joins)
|
||||
js = Qx.get_join_param(joins)
|
||||
@tree[:LEFT_JOIN] = Qx.parse_joins(js)
|
||||
self
|
||||
end
|
||||
|
||||
def add_left_join(*joins)
|
||||
js = Qx.get_join_param(joins)
|
||||
@tree[:LEFT_JOIN] ||= []
|
||||
@tree[:LEFT_JOIN].concat(Qx.parse_joins(js))
|
||||
self
|
||||
end
|
||||
|
||||
def left_outer_join(*joins)
|
||||
js = Qx.get_join_param(joins)
|
||||
@tree[:LEFT_OUTER_JOIN] = Qx.parse_joins(js)
|
||||
self
|
||||
end
|
||||
|
||||
def add_left_outer_join(*joins)
|
||||
js = Qx.get_join_param(joins)
|
||||
@tree[:LEFT_OUTER_JOIN] ||= []
|
||||
@tree[:LEFT_OUTER_JOIN].concat(Qx.parse_joins(js))
|
||||
self
|
||||
end
|
||||
|
||||
def join_lateral(join_name, select_statement, success_condition=true)
|
||||
|
||||
@tree[:JOIN_LATERAL] ||= []
|
||||
@tree[:JOIN_LATERAL] += {name: join_name, select_statement: select_statement, condition: success_condition}
|
||||
self
|
||||
end
|
||||
|
||||
# - INSERT INTO / UPDATE
|
||||
|
||||
# Allows three formats:
|
||||
# insert.values([[col1, col2], [val1, val2], [val3, val3]], options)
|
||||
# insert.values([{col1: val1, col2: val2}, {col1: val3, co2: val4}], options)
|
||||
# insert.values({col1: val1, col2: val2}, options) <- only for single inserts
|
||||
def values(vals)
|
||||
if vals.is_a?(Array) && vals.first.is_a?(Array)
|
||||
cols = vals.first
|
||||
data = vals[1..-1]
|
||||
elsif vals.is_a?(Array) && vals.first.is_a?(Hash)
|
||||
hashes = vals.map { |h| h.sort.to_h } # Make sure hash keys line up with all row data
|
||||
cols = hashes.first.keys
|
||||
data = hashes.map(&:values)
|
||||
elsif vals.is_a?(Hash)
|
||||
cols = vals.keys
|
||||
data = [vals.values]
|
||||
end
|
||||
@tree[:VALUES] = data.map { |vals| vals.map { |d| Qx.quote(d) } }
|
||||
@tree[:INSERT_COLUMNS] = cols.map { |c| Qx.quote_ident(c) }
|
||||
self
|
||||
end
|
||||
|
||||
# A convenience function for setting the same values across all inserted rows
|
||||
def common_values(h)
|
||||
cols = h.keys.map { |col| Qx.quote_ident(col) }
|
||||
data = h.values.map { |val| Qx.quote(val) }
|
||||
@tree[:VALUES] = @tree[:VALUES].map { |row| row.concat(data) }
|
||||
@tree[:INSERT_COLUMNS] = @tree[:INSERT_COLUMNS].concat(cols)
|
||||
self
|
||||
end
|
||||
|
||||
# add timestamps to an insert or update
|
||||
def ts
|
||||
now = "'#{Time.now.utc}'"
|
||||
if @tree[:VALUES]
|
||||
@tree[:INSERT_COLUMNS].concat %w[created_at updated_at]
|
||||
@tree[:VALUES] = @tree[:VALUES].map { |arr| arr.concat [now, now] }
|
||||
elsif @tree[:SET]
|
||||
@tree[:SET] += ", updated_at = #{now}"
|
||||
end
|
||||
self
|
||||
end
|
||||
alias timestamps ts
|
||||
|
||||
def returning(*cols)
|
||||
@tree[:RETURNING] = cols.map { |c| Qx.quote_ident(c) }
|
||||
self
|
||||
end
|
||||
|
||||
# Vals can be a raw SQL string or a hash of data
|
||||
def set(vals)
|
||||
if vals.is_a? Hash
|
||||
vals = vals.map { |key, val| "#{Qx.quote_ident(key)} = #{Qx.quote(val)}" }.join(', ')
|
||||
end
|
||||
@tree[:SET] = vals.to_s
|
||||
self
|
||||
end
|
||||
|
||||
def on_conflict()
|
||||
@tree[:ON_CONFLICT] = true
|
||||
self
|
||||
end
|
||||
|
||||
def conflict_columns(*columns)
|
||||
@tree[:CONFLICT_COLUMNS] = columns
|
||||
self
|
||||
end
|
||||
|
||||
def on_constraint(constraint)
|
||||
@tree[:ON_CONSTRAINT] = constraint
|
||||
self
|
||||
end
|
||||
|
||||
def upsert(on_index, columns=nil)
|
||||
@tree[:CONFLICT_UPSERT] = {index: on_index, cols: columns}
|
||||
self
|
||||
end
|
||||
|
||||
def explain
|
||||
@tree[:EXPLAIN] = true
|
||||
self
|
||||
end
|
||||
|
||||
# -- Helpers!
|
||||
|
||||
def self.fetch(table_name, data, options = {})
|
||||
expr = Qx.select('*').from(table_name)
|
||||
if data.is_a?(Hash)
|
||||
expr = data.reduce(expr) { |acc, pair| acc.and_where("#{pair.first} IN ($vals)", vals: Array(pair.last)) }
|
||||
else
|
||||
expr = expr.where('id IN ($ids)', ids: Array(data))
|
||||
end
|
||||
result = expr.execute(options)
|
||||
result
|
||||
end
|
||||
|
||||
# Given a Qx expression, add a LIMIT and OFFSET for pagination
|
||||
def paginate(current_page, page_length)
|
||||
current_page = 1 if current_page.nil? || current_page < 1
|
||||
limit(page_length).offset((current_page - 1) * page_length)
|
||||
end
|
||||
|
||||
def pp
|
||||
str = parse
|
||||
# Colorize some tokens
|
||||
# TODO indent by paren levels
|
||||
str = str
|
||||
.gsub(/(FROM|WHERE|VALUES|SET|SELECT|UPDATE|INSERT INTO|DELETE FROM)/) { Regexp.last_match(1).to_s.blue.bold }
|
||||
.gsub(/(\(|\))/) { Regexp.last_match(1).to_s.cyan }
|
||||
.gsub('$Q$', "'")
|
||||
str
|
||||
end
|
||||
|
||||
# -- utils
|
||||
|
||||
attr_reader :tree
|
||||
|
||||
# Safely interpolate some data into a SQL expression
|
||||
def self.interpolate_expr(expr, data = {})
|
||||
expr.to_s.gsub(/\$\w+/) do |match|
|
||||
val = data[match.gsub(/[ \$]*/, '').to_sym]
|
||||
vals = val.is_a?(Array) ? val : [val]
|
||||
vals.map { |x| Qx.quote(x) }.join(', ')
|
||||
end
|
||||
end
|
||||
|
||||
# Quote a string for use in sql to prevent injection or weird errors
|
||||
# Always use this for all values!
|
||||
# Just uses double-dollar quoting universally. Should be generally safe and easy.
|
||||
# Will return an unquoted value it it's a Fixnum
|
||||
def self.quote(val)
|
||||
if val.is_a?(Qx)
|
||||
val.parse
|
||||
elsif val.is_a?(Integer)
|
||||
val.to_s
|
||||
elsif val.is_a?(Time)
|
||||
"'" + val.to_s + "'" # single-quoted times for a little better readability
|
||||
elsif val.nil?
|
||||
'NULL'
|
||||
elsif !!val == val # is a boolean
|
||||
val ? "'t'" : "'f'"
|
||||
else
|
||||
'$Q$' + val.to_s + '$Q$'
|
||||
end
|
||||
end
|
||||
|
||||
# Double-quote sql identifiers (or parse Qx trees for subqueries)
|
||||
def self.quote_ident(expr)
|
||||
if expr.is_a?(Qx)
|
||||
Qx.parse(expr.tree)
|
||||
else
|
||||
expr.to_s.split('.').map { |s| s == '*' ? s : "\"#{s}\"" }.join('.')
|
||||
end
|
||||
end
|
||||
|
||||
# Remove a clause from the sql tree
|
||||
def remove_clause(name)
|
||||
name = name.to_s.upcase.tr(' ', '_').to_sym
|
||||
@tree.delete(name)
|
||||
self
|
||||
end
|
||||
|
||||
private # Internal utils
|
||||
|
||||
# Turn join params into something that .parse can use
|
||||
def self.parse_joins(js)
|
||||
js.map { |table, cond, data| [table.is_a?(Qx) ? table.parse : table, Qx.interpolate_expr(cond, data)] }
|
||||
end
|
||||
|
||||
# Given an array, determine if it has the form
|
||||
# [[join_table, join_on, data], ...]
|
||||
# or
|
||||
# [join_table, join_on, data]
|
||||
# Always return the former format
|
||||
def self.get_join_param(js)
|
||||
js.first.is_a?(Array) ? js : [[js.first, js[1], js[2]]]
|
||||
end
|
||||
|
||||
# given either a single hash or a string expr + data, parse it into a single string expression
|
||||
def self.parse_wheres(clauses)
|
||||
clauses.map do |expr, data|
|
||||
if expr.is_a?(Hash)
|
||||
expr.map { |key, val| "#{Qx.quote_ident(key)} IN (#{Qx.quote(val)})" }.join(' AND ')
|
||||
else
|
||||
Qx.interpolate_expr(expr, data)
|
||||
end
|
||||
end
|
||||
end
|
||||
|
||||
# Similar to get_joins_params, except each where clause is a pair, not a triplet
|
||||
def self.get_where_params(ws)
|
||||
ws.first.is_a?(Array) ? ws : [[ws.first, ws[1]]]
|
||||
end
|
||||
|
||||
# given either a single, hash, array of hashes, or csv style, turn it all into csv style
|
||||
# util for INSERT INTO x (y) VALUES z
|
||||
def self.parse_val_params(vals)
|
||||
if vals.is_a?(Array) && vals.first.is_a?(Array)
|
||||
cols = vals.first
|
||||
data = vals[1..-1]
|
||||
elsif vals.is_a?(Array) && vals.first.is_a?(Hash)
|
||||
hashes = vals.map { |h| h.sort.to_h }
|
||||
cols = hashes.first.keys
|
||||
data = hashes.map(&:values)
|
||||
elsif vals.is_a?(Hash)
|
||||
cols = vals.keys
|
||||
data = [vals.values]
|
||||
end
|
||||
[cols, data]
|
||||
end
|
||||
end
|
15
gems/ruby-qx/qx.gemspec
Normal file
15
gems/ruby-qx/qx.gemspec
Normal file
|
@ -0,0 +1,15 @@
|
|||
Gem::Specification.new do |s|
|
||||
s.name = 'qx'
|
||||
s.version = '0.1.1'
|
||||
s.date = '2016-12-05'
|
||||
s.summary = 'SQL expression builder'
|
||||
s.description = 'A expression builder for SQL expressions with Postgresql support'
|
||||
s.authors = ['Jay R Bolton']
|
||||
s.email = 'jayrbolton@gmail.com'
|
||||
s.files = 'lib/qx.rb'
|
||||
s.homepage = 'https://github.com/jayrbolton/qx'
|
||||
s.license = 'MIT'
|
||||
s.add_runtime_dependency 'colorize', '~> 0.8'
|
||||
s.add_runtime_dependency 'activerecord', '>= 3.0'
|
||||
s.add_development_dependency 'minitest', '~> 5.9'
|
||||
end
|
20
gems/ruby-qx/test/UpsertTest.rb
Normal file
20
gems/ruby-qx/test/UpsertTest.rb
Normal file
|
@ -0,0 +1,20 @@
|
|||
require './lib/qx.rb'
|
||||
|
||||
require 'minitest/autorun'
|
||||
class UpsertTest < Minitest::Test
|
||||
def setup
|
||||
|
||||
end
|
||||
|
||||
def test_upsert
|
||||
table = 'x'
|
||||
column1 = "a"
|
||||
column2 = 'b'
|
||||
idx = "idx_something_more"
|
||||
|
||||
result = Qx.insert_into(table).values({column1: column1, column2: column2}).on_conflict.upsert(idx).parse
|
||||
|
||||
expected = %Q(INSERT INTO "#{table}" ("column1", "column2") VALUES ($Q$#{column1}$Q$, $Q$#{column2}$Q$) ON CONFLICT ON CONSTRAINT #{idx} DO UPDATE SET "column1" = EXCLUDED."column1", "column2" = EXCLUDED."column2")
|
||||
assert_equal(expected, result)
|
||||
end
|
||||
end
|
275
gems/ruby-qx/test/qx_test.rb
Normal file
275
gems/ruby-qx/test/qx_test.rb
Normal file
|
@ -0,0 +1,275 @@
|
|||
require './lib/qx.rb'
|
||||
require 'pg'
|
||||
require 'minitest/autorun'
|
||||
require 'pry'
|
||||
|
||||
ActiveRecord::Base.establish_connection('postgres://admin:password@localhost/qx_test')
|
||||
tm = PG::BasicTypeMapForResults.new(ActiveRecord::Base.connection.raw_connection)
|
||||
Qx.config(type_map: tm)
|
||||
# Execute test schema
|
||||
Qx.execute_file('./test/test_schema.sql')
|
||||
|
||||
class QxTest < Minitest::Test
|
||||
|
||||
def setup
|
||||
end
|
||||
|
||||
# Let's just test that the schema was executed
|
||||
def test_execute_file
|
||||
email = 'uzzzr@example.com'
|
||||
result = Qx.execute_file('./test/test_insert_user.sql', email: email, id: 1).last
|
||||
Qx.delete_from(:users).where(id: 1).ex
|
||||
assert_equal email, result['email']
|
||||
end
|
||||
|
||||
def test_select_from
|
||||
parsed = Qx.select(:id, "name").from(:table_name).parse
|
||||
assert_equal parsed, %Q(SELECT id, name FROM table_name)
|
||||
end
|
||||
def test_select_distinct_on
|
||||
parsed = Qx.select(:id, "name").distinct_on(:distinct_col1, :distinct_col2).from(:table_name).parse
|
||||
assert_equal parsed, %Q(SELECT DISTINCT ON (distinct_col1, distinct_col2) id, name FROM table_name)
|
||||
end
|
||||
def test_select_distinct
|
||||
parsed = Qx.select(:id, "name").distinct.from(:table_name).parse
|
||||
assert_equal parsed, %Q(SELECT DISTINCT id, name FROM table_name)
|
||||
end
|
||||
|
||||
def test_select_as
|
||||
parsed = Qx.select(:id, "name").from(:table_name).as(:alias).parse
|
||||
assert_equal parsed, %Q((SELECT id, name FROM table_name) AS "alias")
|
||||
end
|
||||
|
||||
def test_select_where
|
||||
parsed = Qx.select(:id, "name").from(:table_name).where("x = $y OR a = $b", y: 1, b: 2).parse
|
||||
assert_equal parsed, %Q(SELECT id, name FROM table_name WHERE (x = 1 OR a = 2))
|
||||
end
|
||||
def test_select_where_hash_array
|
||||
parsed = Qx.select(:id, "name").from(:table_name).where([x: 1], ["y = $n", {n: 2}]).parse
|
||||
assert_equal parsed, %Q(SELECT id, name FROM table_name WHERE ("x" IN (1)) AND (y = 2))
|
||||
end
|
||||
def test_select_and_where
|
||||
parsed = Qx.select(:id, "name").from(:table_name).where("x = $y", y: 1).and_where("a = $b", b: 2).parse
|
||||
assert_equal parsed, %Q(SELECT id, name FROM table_name WHERE (x = 1) AND (a = 2))
|
||||
end
|
||||
def test_select_and_where_hash
|
||||
parsed = Qx.select(:id, "name").from(:table_name).where("x = $y", y: 1).and_where(a: 2).parse
|
||||
assert_equal parsed, %Q(SELECT id, name FROM table_name WHERE (x = 1) AND ("a" IN (2)))
|
||||
end
|
||||
|
||||
def test_select_and_group_by
|
||||
parsed = Qx.select(:id, "name").from(:table_name).group_by("col1", "col2").parse
|
||||
assert_equal parsed, %Q(SELECT id, name FROM table_name GROUP BY col1, col2)
|
||||
end
|
||||
|
||||
def test_select_and_order_by
|
||||
parsed = Qx.select(:id, "name").from(:table_name).order_by("col1", ["col2", "DESC NULLS LAST"]).parse
|
||||
assert_equal parsed, %Q(SELECT id, name FROM table_name ORDER BY col1 , col2 DESC NULLS LAST)
|
||||
end
|
||||
|
||||
def test_select_having
|
||||
parsed = Qx.select(:id, "name").from(:table_name).having("COUNT(col1) > $n", n: 1).parse
|
||||
assert_equal parsed, %Q(SELECT id, name FROM table_name HAVING (COUNT(col1) > 1))
|
||||
end
|
||||
def test_select_and_having
|
||||
parsed = Qx.select(:id, "name").from(:table_name).having("COUNT(col1) > $n", n: 1).and_having("SUM(col2) > $m", m: 2).parse
|
||||
assert_equal parsed, %Q(SELECT id, name FROM table_name HAVING (COUNT(col1) > 1) AND (SUM(col2) > 2))
|
||||
end
|
||||
|
||||
def test_select_limit
|
||||
parsed = Qx.select(:id, "name").from(:table_name).limit(10).parse
|
||||
assert_equal parsed, %Q(SELECT id, name FROM table_name LIMIT 10)
|
||||
end
|
||||
def test_select_offset
|
||||
parsed = Qx.select(:id, "name").from(:table_name).offset(10).parse
|
||||
assert_equal parsed, %Q(SELECT id, name FROM table_name OFFSET 10)
|
||||
end
|
||||
|
||||
def test_select_join
|
||||
parsed = Qx.select(:id, "name").from(:table_name).join(['assoc1', 'assoc1.table_name_id=table_name.id']).parse
|
||||
assert_equal parsed, %Q(SELECT id, name FROM table_name JOIN assoc1 ON assoc1.table_name_id=table_name.id)
|
||||
end
|
||||
def test_select_add_join
|
||||
parsed = Qx.select(:id, "name").from(:table_name).join('assoc1', 'assoc1.table_name_id=table_name.id')
|
||||
.add_join(['assoc2', 'assoc2.table_name_id=table_name.id']).parse
|
||||
assert_equal parsed, %Q(SELECT id, name FROM table_name JOIN assoc1 ON assoc1.table_name_id=table_name.id JOIN assoc2 ON assoc2.table_name_id=table_name.id)
|
||||
end
|
||||
def test_select_left_join
|
||||
parsed = Qx.select(:id, "name").from(:table_name).left_join(['assoc1', 'assoc1.table_name_id=table_name.id']).parse
|
||||
assert_equal parsed, %Q(SELECT id, name FROM table_name LEFT JOIN assoc1 ON assoc1.table_name_id=table_name.id)
|
||||
end
|
||||
def test_select_add_left_join
|
||||
parsed = Qx.select(:id, "name").from(:table_name).left_join('assoc1', 'assoc1.table_name_id=table_name.id')
|
||||
.add_left_join(['assoc2', 'assoc2.table_name_id=table_name.id']).parse
|
||||
assert_equal parsed, %Q(SELECT id, name FROM table_name LEFT JOIN assoc1 ON assoc1.table_name_id=table_name.id LEFT JOIN assoc2 ON assoc2.table_name_id=table_name.id)
|
||||
end
|
||||
|
||||
def test_select_where_subquery
|
||||
parsed = Qx.select(:id, "name").from(:table_name).where("id IN ($ids)", ids: Qx.select("id").from("assoc")).parse
|
||||
assert_equal parsed, %Q(SELECT id, name FROM table_name WHERE (id IN (SELECT id FROM assoc)))
|
||||
end
|
||||
|
||||
def test_select_join_subquery
|
||||
parsed = Qx.select(:id).from(:table).join([Qx.select(:id).from(:assoc).as(:assoc), "assoc.table_id=table.id"]).parse
|
||||
assert_equal parsed, %Q(SELECT id FROM table JOIN (SELECT id FROM assoc) AS "assoc" ON assoc.table_id=table.id)
|
||||
end
|
||||
|
||||
def test_select_from_subquery
|
||||
parsed = Qx.select(:id).from(Qx.select(:id).from(:table).as(:table)).parse
|
||||
assert_equal parsed, %Q(SELECT id FROM (SELECT id FROM table) AS "table")
|
||||
end
|
||||
|
||||
def test_select_integration
|
||||
parsed = Qx.select(:id)
|
||||
.from(:table)
|
||||
.join([Qx.select(:id).from(:assoc).as(:assoc), 'assoc.table_id=table.id'])
|
||||
.left_join(['lefty', 'lefty.table_id=table.id'])
|
||||
.where('x = $n', n: 1)
|
||||
.and_where('y = $n', n: 1)
|
||||
.group_by(:x)
|
||||
.order_by(:y)
|
||||
.having('COUNT(x) > $n', n: 1)
|
||||
.and_having('COUNT(y) > $n', n: 1)
|
||||
.limit(10)
|
||||
.offset(10)
|
||||
.parse
|
||||
assert_equal parsed, %Q(SELECT id FROM table JOIN (SELECT id FROM assoc) AS "assoc" ON assoc.table_id=table.id LEFT JOIN lefty ON lefty.table_id=table.id WHERE (x = 1) AND (y = 1) GROUP BY x HAVING (COUNT(x) > 1) AND (COUNT(y) > 1) ORDER BY y LIMIT 10 OFFSET 10)
|
||||
end
|
||||
|
||||
def test_insert_into_values_hash
|
||||
parsed = Qx.insert_into(:table_name).values(x: 1).parse
|
||||
assert_equal parsed, %Q(INSERT INTO "table_name" ("x") VALUES (1))
|
||||
end
|
||||
def test_insert_into_values_hash_array
|
||||
parsed = Qx.insert_into(:table_name).values([{x: 1}, {x: 2}]).parse
|
||||
assert_equal parsed, %Q(INSERT INTO "table_name" ("x") VALUES (1), (2))
|
||||
end
|
||||
def test_insert_into_values_csv_style
|
||||
parsed = Qx.insert_into(:table_name).values([['x'], [1], [2]]).parse
|
||||
assert_equal parsed, %Q(INSERT INTO "table_name" ("x") VALUES (1), (2))
|
||||
end
|
||||
def test_insert_into_values_common_values
|
||||
parsed = Qx.insert_into(:table_name).values([{x: 'bye'}, {x: 'hi'}]).common_values(z: 1).parse
|
||||
assert_equal parsed, %Q(INSERT INTO "table_name" ("x", "z") VALUES ($Q$bye$Q$, 1), ($Q$hi$Q$, 1))
|
||||
end
|
||||
def test_insert_into_values_timestamps
|
||||
parsed = Qx.insert_into(:table_name).values(x: 1).ts.parse
|
||||
assert_equal parsed, %Q(INSERT INTO "table_name" ("x", created_at, updated_at) VALUES (1, '#{Time.now.utc}', '#{Time.now.utc}'))
|
||||
end
|
||||
def test_insert_into_values_returning
|
||||
parsed = Qx.insert_into(:table_name).values(x: 1).returning('*').parse
|
||||
assert_equal parsed, %Q(INSERT INTO "table_name" ("x") VALUES (1) RETURNING *)
|
||||
end
|
||||
def test_insert_into_select
|
||||
parsed = Qx.insert_into(:table_name, ['hi']).select('hi').from(:table2).where("x=y").parse
|
||||
assert_equal parsed, %Q(INSERT INTO "table_name" ("hi") SELECT hi FROM table2 WHERE (x=y))
|
||||
end
|
||||
|
||||
def test_update_set
|
||||
parsed = Qx.update(:table_name).set(x: 1).where("y = 2").parse
|
||||
assert_equal parsed, %Q(UPDATE "table_name" SET "x" = 1 WHERE (y = 2))
|
||||
end
|
||||
def test_update_timestamps
|
||||
now = Time.now.utc
|
||||
parsed = Qx.update(:table_name).set(x: 1).where("y = 2").timestamps.parse
|
||||
assert_equal parsed, %Q(UPDATE "table_name" SET "x" = 1, updated_at = '#{now}' WHERE (y = 2))
|
||||
end
|
||||
|
||||
def test_update_on_conflict
|
||||
Qx.update(:table_name).set(x: 1).where("y = 2").on_conflict(:nothing).parse
|
||||
assert_equal parsed, %Q(UPDATE "table_name" SET "x" = 1 WHERE (y = 2) ON CONFLICT DO NOTHING)
|
||||
end
|
||||
|
||||
def test_insert_timestamps
|
||||
now = Time.now.utc
|
||||
parsed = Qx.insert_into(:table_name).values({x: 1}).ts.parse
|
||||
assert_equal parsed, %Q(INSERT INTO "table_name" ("x", created_at, updated_at) VALUES (1, '#{now}', '#{now}'))
|
||||
end
|
||||
|
||||
def test_delete_from
|
||||
parsed = Qx.delete_from(:table_name).where(x: 1).parse
|
||||
assert_equal parsed, %Q(DELETE FROM "table_name" WHERE ("x" IN (1)))
|
||||
end
|
||||
|
||||
def test_pagination
|
||||
parsed = Qx.select(:x).from(:y).paginate(4, 30).parse
|
||||
assert_equal parsed, %Q(SELECT x FROM y LIMIT 30 OFFSET 90)
|
||||
end
|
||||
|
||||
def test_execute_string
|
||||
result = Qx.execute("SELECT * FROM (VALUES ($x)) AS t", x: 'x')
|
||||
assert_equal result, [{'column1' => 'x'}]
|
||||
end
|
||||
def test_execute_format_csv
|
||||
result = Qx.execute("SELECT * FROM (VALUES ($x)) AS t", {x: 'x'}, {format: 'csv'})
|
||||
assert_equal result, [['column1'], ['x']]
|
||||
end
|
||||
def test_execute_on_instances
|
||||
result = Qx.insert_into(:users).values(id: 1, email: 'uzr@example.com').execute
|
||||
result = Qx.execute(Qx.select("*").from(:users).limit(1))
|
||||
assert_equal result, [{'id' => 1, 'email' => 'uzr@example.com'}]
|
||||
Qx.delete_from(:users).where(id: 1).execute
|
||||
end
|
||||
|
||||
def test_explain
|
||||
parsed = Qx.select("*").from("table_name").explain.parse
|
||||
assert_equal parsed, %Q(EXPLAIN SELECT * FROM table_name)
|
||||
end
|
||||
|
||||
# Manually test this one for now
|
||||
def test_pp_select
|
||||
pp = Qx.select("id, name").from("table_name").where(status: 'active').and_where(id: Qx.select("id").from("roles").where(name: "admin")).pp
|
||||
pp2 = Qx.insert_into(:table_name).values([x: 1, y: 2]).pp
|
||||
pp3 = Qx.update(:table_name).set(x: 1, y: 2).where(z: 1, a: 22).pp
|
||||
pp_delete = Qx.delete_from(:table_name).where(id: 123).pp
|
||||
puts ""
|
||||
puts "--- pretty print"
|
||||
puts pp
|
||||
puts pp2
|
||||
puts pp3
|
||||
puts pp_delete
|
||||
puts "---"
|
||||
end
|
||||
|
||||
def test_to_json
|
||||
parsed = Qx.select(:id).from(:users).to_json(:t).parse
|
||||
assert_equal parsed, %Q(SELECT array_to_json(array_agg(row_to_json(t))) FROM (SELECT id FROM users) AS "t")
|
||||
end
|
||||
|
||||
def test_to_json_nested
|
||||
definitions = Qx.select(:part_of_speech, :body)
|
||||
.from(:definitions)
|
||||
.where("word_id=words.id")
|
||||
.order_by("position ASC")
|
||||
.to_json(:ds)
|
||||
.as("definitions")
|
||||
parsed = Qx.select(:text, :pronunciation, definitions)
|
||||
.from(:words)
|
||||
.where("text='autumn'")
|
||||
.to_json(:ws)
|
||||
.parse
|
||||
assert_equal parsed, "SELECT array_to_json(array_agg(row_to_json(ws))) FROM (SELECT text, pronunciation, (SELECT array_to_json(array_agg(row_to_json(ds))) FROM (SELECT part_of_speech, body FROM definitions WHERE (word_id=words.id) ORDER BY position ASC ) AS \"ds\") AS \"definitions\" FROM words WHERE (text='autumn')) AS \"ws\""
|
||||
end
|
||||
|
||||
def test_copy_csv_execution
|
||||
data = {'id' => '1', 'email' => 'uzr@example.com'}
|
||||
filename = '/tmp/qx-test.csv'
|
||||
Qx.insert_into(:users).values(data).ex
|
||||
copy = Qx.select("*").from("users").execute(copy_csv: filename)
|
||||
contents = File.open(filename, 'r').read
|
||||
csv_data = contents.split("\n").map{|l| l.split(",")}
|
||||
headers = csv_data.first
|
||||
row = csv_data.last
|
||||
assert_equal data.keys, headers
|
||||
assert_equal data.values, row
|
||||
end
|
||||
|
||||
def test_remove_clause
|
||||
expr = Qx.select("*").from("table").limit(1)
|
||||
expr = expr.remove_clause('limit')
|
||||
assert_equal "SELECT * FROM table", expr.parse
|
||||
end
|
||||
|
||||
|
||||
|
||||
end
|
1
gems/ruby-qx/test/test_insert_user.sql
Normal file
1
gems/ruby-qx/test/test_insert_user.sql
Normal file
|
@ -0,0 +1 @@
|
|||
INSERT INTO users (id, email) VALUES ($id, $email) RETURNING *;
|
13
gems/ruby-qx/test/test_schema.sql
Normal file
13
gems/ruby-qx/test/test_schema.sql
Normal file
|
@ -0,0 +1,13 @@
|
|||
DROP SCHEMA IF EXISTS public CASCADE;
|
||||
CREATE SCHEMA public;
|
||||
GRANT ALL ON SCHEMA public TO admin;
|
||||
|
||||
-- users
|
||||
CREATE TABLE users (
|
||||
id integer NOT NULL
|
||||
, email character varying(255)
|
||||
);
|
||||
CREATE SEQUENCE users_id_seq START WITH 1 INCREMENT BY 1 NO MINVALUE NO MAXVALUE CACHE 1;
|
||||
ALTER SEQUENCE users_id_seq OWNED BY users.id;
|
||||
ALTER TABLE ONLY users ALTER COLUMN id SET DEFAULT nextval('users_id_seq'::regclass);
|
||||
|
Loading…
Reference in a new issue