diff --git a/README.md b/README.md index 2949548..e6fb495 100644 --- a/README.md +++ b/README.md @@ -7,7 +7,7 @@ You've been fighting yet another abstraction... Aren't you fed up with object-relation magic? But wait, here comes a humongous migration. Is ActiveRecord making you sick? -To hell with that monstrous ARel expression! +To hell with that monstrous Arel expression! Tell the truth, you were just wishing That it was as simple as a here-string. But could it keep some Ruby notation @@ -21,13 +21,11 @@ No bullshit No layers No wrappers No smarty-pants -No weird stance No sexy +No nonsense No AST No lazy loading No crazy mapping -No pretense -No nonsense What you write is what you get: readable and obvious What you write is what you meant: tasty and delicious @@ -36,6 +34,314 @@ Wait, it doesn't execute!? Just use your fave client gem, isn't that cute? ``` +## Motivation + +There are many a time where you end up knowing exactly what SQL query you want, +yet have to wrap your head around for the ORM to produce it, which is when the +point of such a layer is entirely defeated. Concatenating and interpolating +only goes so far. + +As ActiveRecord grows, a significant decision has been taken in the Rails team +to turn Arel into a library purely internal to ActiveRecord: the whole of it is +basically considered internal and private, and only ActiveRecord's public +interface should be used. Unfortunately, some highly dynamic, complex queries +simply cannot be built using ActiveRecord, and concatenating strings to build +SQL fragments and clauses simply does not cut it. + +## Philosophy + +- It must be readable as being SQL +- Yet it must be as much Ruby syntax and types as possible +- It must be able to produce fragments for others to use +- And somehow be composable enough +- It must not rely on metaprogramming magic +- Nor need monkeypatching core types + +## Design + +There are two goals to this library: + +- query building +- query execution + +Query building is about assembling a string containing a partial or complete +query that you will later pass on to be executed by an executor. + +Query execution is about writing a query that will be executed on the spot. + +There are also non-goals to this library: + +- be any sort of ORM +- or any sort of abstraction layer +- or any sort of query optimiser + +## Usage + +`Rebel::SQL` is a module that contains building and execution features, and +output ANSI-style SQL. + +`Rebel::SQL()` is a function that produces a customised module enabling support +for alternative dialects, and when passed a block, allows you to write things +more literally. + +Ruby types are best-effort mapped to SQL entities in a simple, regular way: + +- Symbols map to quoted SQL names such as tables, columns, aliases. +- Strings map to strings. Always. (Quote style can be configured). +- Integers and floats map to, well, integers and floats. +- Date, Time and DateTime map to their ISO 8601 string representation +- Booleans map to their respective ANSI literals (unless overriden by + configuration). +- `nil` maps to `NULL` and is expected to have the same "unknown" semantic + +Variable arguments are generally used. Hashes, depending on context, map to: + +- `=` equality or `IN` operators joined by `AND` +- `=` assignment operator joined by commas + +## Examples + +### Query building + +```ruby +require 'rebel' + +# Here's a typical query +Rebel::SQL.select :id, from: :customers, where: { :first_name => 'John', :last_name => 'Doe' } +=> SELECT "id" FROM "customers" WHERE "first_name" = 'John' AND "last_name" = 'Doe' + +# More args give more columns +Rebel::SQL.select :first_name, :last_name, from: :customers, where: { :id => [1, 2, 3] } +=> SELECT "first_name", "last_name" FROM "customers" WHERE "id" IN (1, 2, 3) + +# * is special-cased for names +Rebel::SQL.select :*, from: :customers, where: { :id => [1, 2, 3] } +=> SELECT * FROM "customers" WHERE "id" IN (1, 2, 3) + +# You can emit fragments to produce clauses +puts Rebel::SQL.and_clause :id => [1, 2, 3], :country => 'GB' +=> "id" IN (1, 2, 3) AND "country" = 'GB' +Rebel::SQL.where? :id => [1, 2, 3], :country => 'GB' +=> WHERE "id" IN (1, 2, 3) AND "country" = 'GB' + +# Here the question mark means where? swallows nil arguments: maybe it's a Maybe monad +Rebel::SQL.where?(nil) +=> nil + +# Let's emit join clauses +Rebel::SQL.join(:contracts, on: :customer_id => :id) +#=> JOIN "contracts" ON "customer_id" = "id" +Rebel::SQL.join(:contracts).on(:customer_id => :id) +#=> JOIN "contracts" ON "customer_id" = "id" + +# :contracts might have an :id too, so we can disambiguate those columns +Rebel::SQL.join(:contracts).on(:'contracts.customer_id' => :'customers.id') +#=> JOIN "contracts" ON "contracts"."customer_id" = "customers"."id" + +# Other types of join are obviously available +Rebel::SQL.inner_join(:contracts).on(:'contracts.customer_id' => :'customers.id') +#=> INNER JOIN "contracts" ON "contracts"."customer_id" = "customers"."id" +Rebel::SQL.outer_join(:contracts).on(:'contracts.customer_id' => :'customers.id') +#=> OUTER JOIN "contracts" ON "contracts"."customer_id" = "customers"."id" +Rebel::SQL.left_outer_join(:contracts).on(:'contracts.customer_id' => :'customers.id') +#=> LEFT OUTER JOIN "contracts" ON "contracts"."customer_id" = "customers"."id" +Rebel::SQL.right_outer_join(:contracts).on(:'contracts.customer_id' => :'customers.id') +#=> RIGHT OUTER JOIN "contracts" ON "contracts"."customer_id" = "customers"."id" + +# The type of join can be split off. Again, note the question mark. +Rebel::SQL.inner? Rebel::SQL.join(:contracts).on(:'contracts.customer_id' => :'customers.id') +#=> INNER JOIN "contracts" ON "contracts"."customer_id" = "customers"."id" +Rebel::SQL.left? Rebel::SQL.outer_join(:contracts).on(:'contracts.customer_id' => :'customers.id') +#=> LEFT OUTER JOIN "contracts" ON "contracts"."customer_id" = "customers"."id" + +# And in a full query +Rebel::SQL.select :'customers.id', :'contracts.id', + from: :customers, + where: { :first_name => 'John', :last_name => 'Doe' }, + inner: Rebel::SQL.join(:contracts).on(:'contracts.customer_id' => :'customers.id'), + order: Rebel::SQL.by(:'customer.age').asc +#=> SELECT "customers"."id", "contracts"."id" +# FROM "customers" +# INNER JOIN "contracts" ON "contracts"."customer_id" = "customers"."id" +# WHERE "first_name" = 'John' AND "last_name" = 'Doe' +# ORDER BY "customer"."age" ASC + +# All those Rebel::SQL can get unwieldy, so let's reduce the noise +Rebel::SQL() do + select :'customers.id', :'contracts.id', + from: :customers, + where: { :first_name => 'John', :last_name => 'Doe' }, + inner: join(:contracts).on(:'contracts.customer_id' => :'customers.id'), + order: by(:'customer.age').asc +end +#=> SELECT "customers"."id", "contracts"."id" +# FROM "customers" +# INNER JOIN "contracts" ON "contracts"."customer_id" = "customers"."id" +# WHERE "first_name" = 'John' AND "last_name" = 'Doe' +# ORDER BY "customer"."age" ASC + +# Now, that function can be used to make things different +Rebel::SQL.name(:foo) +#=> "foo" +Rebel::SQL(identifier_quote: '`').name(:foo) +#=> `foo` +Rebel::SQL.value(true) +#=> TRUE +Rebel::SQL(true_literal: '1').value(true) +#=> 1 +Rebel::SQL(true_literal: '1') { select value(true) } +#=> SELECT 1 + +# While we're at it, let's call arbitrary functions +Rebel::SQL() { select function('NOW') } +#=> SELECT NOW() +Rebel::SQL() { select function('LENGTH', "a string") } +#=> SELECT LENGTH('a string') +Rebel::SQL() { select function('COUNT', :id), from: :customers, where: { :age => 42 } } +#=> SELECT COUNT("id") FROM "customers" WHERE "age" = 42 +Rebel::SQL() { select count(:id), from: :customers, where: { :age => 42 } } +#=> SELECT COUNT("id") FROM "customers" WHERE "age" = 42 + +# And throw in some aliases +Rebel::SQL() { select function('LENGTH', "a string").as(:length) } +#=> SELECT LENGTH('a string') AS "length" +Rebel::SQL() { select name(:id).as(:customer_id), from: :customers } +#=> SELECT "id" AS "customer_id" FROM "customers" +Rebel::SQL() { select count(:id).as(:count), from: :customers, where: { :age => 42 } } +#=> SELECT COUNT("id") FROM "customers" WHERE "age" = 42 + +# While we're counting things, let's group results +Rebel::SQL() { select count(:id).as(:count), :country, from: :customers, group: by(:country).having(count(:customer_id) => 5) } +#=> SELECT COUNT("id") AS "count", "country" FROM "customers" GROUP BY "country" HAVING COUNT("customer_id") = 5 + +# Passing a hash does a best effort to map Ruby to SQL +Rebel::SQL() { select :id, from: :customers, where: { :age => 42 } } +#=> SELECT "id" FROM "customers" WHERE "age" = 42 +Rebel::SQL() { select :id, from: :customers, where: { :age => [20, 21, 22] } } +#=> SELECT "id" FROM "customers" WHERE "age" IN (20, 21, 22) +Rebel::SQL() { select :id, from: :customers, where: { :age => nil } } +#=> SELECT "id" FROM "customers" WHERE "age" IS NULL + +# Using operators ensures the expected SQL operator is used +Rebel::SQL() { select :id, from: :customers, where: name(:age).eq(42) } +#=> SELECT "id" FROM "customers" WHERE "age" = 42 +Rebel::SQL() { select :id, from: :customers, where: name(:age).eq(nil) } +#=> SELECT "id" FROM "customers" WHERE "age" = NULL +Rebel::SQL() { select :id, from: :customers, where: name(:age).ne(42) } +#=> SELECT "id" FROM "customers" WHERE "age" != NULL +Rebel::SQL() { select :id, from: :customers, where: name(:age).is(42) } +#=> SELECT "id" FROM "customers" WHERE "age" IS 42 +Rebel::SQL() { select :id, from: :customers, where: name(:age).is(nil) } +#=> SELECT "id" FROM "customers" WHERE "age" IS NULL +Rebel::SQL() { select :id, from: :customers, where: name(:age).is_not(nil) } +#=> SELECT "id" FROM "customers" WHERE "age" IS NOT NULL + +# Other operators are available +Rebel::SQL() { select :id, from: :customers, where: name(:age).ge(42) } +#=> SELECT "id" FROM "customers" WHERE "age" >= 42 +Rebel::SQL() { select :id, from: :customers, where: name(:age).in(21, 22, 23) } +#=> SELECT "id" FROM "customers" WHERE "age" IN (21, 22, 23) +Rebel::SQL() { select :id, from: :customers, where: name(:first_name).like("J%") } +#=> SELECT "id" FROM "customers" WHERE "first_name" LIKE "J%" + +# Aliases to overload operators are available +Rebel::SQL() { select :id, from: :customers, where: name(:age) == 42 } +#=> SELECT "id" FROM "customers" WHERE "age" = 42 +Rebel::SQL() { select :id, from: :customers, where: name(:age) < 42 } +#=> SELECT "id" FROM "customers" WHERE "age" < 42 +Rebel::SQL() { select :id, from: :customers, where: name(:age) >= 42 } +#=> SELECT "id" FROM "customers" WHERE "age" >= 42 +Rebel::SQL() { select :id, from: :customers, where: name(:age) != 42 } +#=> SELECT "id" FROM "customers" WHERE "age" != 42 + +# Conditions can be combined +Rebel::SQL() { select :id, from: :customers, where: name(:age).gt(42).or(name(:age).lt(21)) } +#=> SELECT "id" FROM "customers" WHERE ("age" > 42 OR "age" < 21) +Rebel::SQL() { select :id, from: :customers, where: (name(:age) < 42).and(name(:age) > 21) } +#=> SELECT "id" FROM "customers" WHERE ("age" < 42 AND "age" > 21) + +# Binary-wise operators can be used to tie conditions +# WARNING: Usefulness if this hack is still debated. It might be removed in the future. +Rebel::SQL() { select :id, from: :customers, where: ((name(:age) > 42) | (name(:age) < 21)) } +#=> SELECT "id" FROM "customers" WHERE ("age" > 42 OR "age" < 21) +Rebel::SQL() { select :id, from: :customers, where: name(:age).lt(42) & (name(:age).gt(21)) } +#=> SELECT "id" FROM "customers" WHERE ("age" < 42 AND "age" > 21) + +``` + +### Query execution + +If you provide Rebel::SQL an environment within which a query executor is +available, queries can be executed directly. + +```ruby +class CreateTableCustomers + include Rebel::SQL + + # provide a connection that responds to exec(query) + def conn + @conn ||= PG.connect( dbname: 'sales' ) + end + + # remember that SQL() returns a module! + include Rebel::SQL(true_literal: '1', false_literal: '0') + + # alternatively, redefine the provided exec (which calls conn.exec) + def exec(query) + @db ||= SQLite3::Database.new "test.db" + @db.execute(query) + end + + def up + create_table :customers, { + id: 'SERIAL', + name: 'VARCHAR(255)', + address: 'VARCHAR(255)', + city: 'VARCHAR(255)', + zip: 'VARCHAR(255)', + country: 'VARCHAR(255)', + } + + insert_into :customers, + { name: 'Lewis Caroll', address: '1, Alice St.', city: 'Oxford', zip: '1865', country: 'Wonderland' }, + { name: 'Neal Stephenson', address: '2, Hiro Blvd.', city: 'Los Angeles', zip: '1992', country: 'Metaverse' } + + results = select :name, :country, from: :customers + + update :customers, set: { city: 'FooTown' }, where: { zip: 1234 } + + delete_from :customers, where: { zip: 1234 } + + truncate :customers + end + + def down + drop_table :customers + end +end +``` + +## FAQ + +### X is missing/database specific, how do I write it? + +You can use `Rebel::SQL.raw("whatever")` and drop it in. + +### Why the weird syntax like `inner: join` instead of `inner_join`? + +This allows for a more uniform interface as well as not monkeypatching core types. + +### Can I write nonsensical SQL with this? + +Yes. Just as you can write nonsensical SQL in SQL. + +### Your query builder is not using an AST. + +That's not a question. You're welcome to implement one that does though, and if +it leverages the visitor pattern, allocates a trajillion objects along the way +and manages to produce invalid SQL in some corner cases, well congratulations +for reimplementing Arel. + ## License MIT diff --git a/lib/rebel/sql.rb b/lib/rebel/sql.rb index 3eb3b60..b5216e8 100644 --- a/lib/rebel/sql.rb +++ b/lib/rebel/sql.rb @@ -1,4 +1,6 @@ -module Rebel::SQL +require 'date' + +module Rebel::SQLQ attr_reader :conn def exec(query) @@ -13,13 +15,18 @@ module Rebel::SQL exec(Rebel::SQL.drop_table(table_name)) end - def select(*fields, from: nil, where: nil, inner: nil, left: nil, right: nil) + def select(*fields, distinct: nil, from: nil, where: nil, inner: nil, left: nil, right: nil, group: nil, order: nil, limit: nil, offset: nil) exec(Rebel::SQL.select(*fields, + distinct: distinct, from: from, where: where, inner: inner, left: left, - right: right)) + right: right, + group: group, + order: order, + limit: limit, + offset: offset)) end def insert_into(table_name, *rows) @@ -49,7 +56,9 @@ module Rebel::SQL def outer_join(table, on: nil) Rebel::SQL.outer_join(table, on: on) end +end +module Rebel class Raw < String def wants_parens! @wants_parens = true @@ -62,7 +71,7 @@ module Rebel::SQL end def parens - Raw.new("(#{self})") + sql.raw("(#{self})") end def parens? @@ -70,7 +79,7 @@ module Rebel::SQL end def as(n) - Raw.new(self + " AS #{Rebel::SQL.name(n)}") + sql.raw(self + " AS #{sql.name(n)}") end def as?(n) @@ -78,150 +87,155 @@ module Rebel::SQL end def on(*clause) - Raw.new(self + " ON #{Rebel::SQL.and_clause(*clause)}") + sql.raw(self + " ON #{sql.and_clause(*clause)}") end def on?(*clause) clause.any? ? on(*clause) : self end - def and(*clause) - Raw.new("#{self.parens?} AND #{Rebel::SQL.and_clause(*clause)}") + def having(*clause) + sql.raw(self + " HAVING #{sql.and_clause(*clause)}") end + def asc + sql.raw(self + " ASC") + end + + def desc + sql.raw(self + " DESC") + end + + def and(*clause) + sql.raw("#{self.parens?} AND #{sql.and_clause(*clause)}") + end + alias & and + def or(*clause) - Raw.new("#{self} OR #{Rebel::SQL.and_clause(*clause)}").wants_parens! + sql.raw("#{self} OR #{sql.and_clause(*clause)}").wants_parens! end + alias | or def eq(n) - case n - when nil - Raw.new("#{self} IS NULL") - else - Raw.new("#{self} = #{Rebel::SQL.name_or_value(n)}") - end + sql.raw("#{self} = #{sql.name_or_value(n)}") end alias == eq - alias is eq + + def is(n) + sql.raw("#{self} IS #{sql.name_or_value(n)}") + end def ne(n) - case n - when nil - Raw.new("#{self} IS NOT NULL") - else - Raw.new("#{self} != #{Rebel::SQL.name_or_value(n)}") - end + sql.raw("#{self} != #{sql.name_or_value(n)}") end alias != ne + def is_not(n) + sql.raw("#{self} IS NOT #{sql.name_or_value(n)}") + end + def lt(n) - Raw.new("#{self} < #{Rebel::SQL.name_or_value(n)}") + sql.raw("#{self} < #{sql.name_or_value(n)}") end alias < lt def gt(n) - Raw.new("#{self} > #{Rebel::SQL.name_or_value(n)}") + sql.raw("#{self} > #{sql.name_or_value(n)}") end alias > gt def le(n) - Raw.new("#{self} <= #{Rebel::SQL.name_or_value(n)}") + sql.raw("#{self} <= #{sql.name_or_value(n)}") end alias <= le def ge(n) - Raw.new("#{self} >= #{Rebel::SQL.name_or_value(n)}") + sql.raw("#{self} >= #{sql.name_or_value(n)}") end alias >= ge def in(*v) - Raw.new("#{self} IN (#{Rebel::SQL.values(*v)})") + sql.raw("#{self} IN (#{sql.values(*v)})") + end + + def not_in(*v) + sql.raw("#{self} NOT IN (#{sql.values(*v)})") end def like(n) - Raw.new("#{self} LIKE #{Rebel::SQL.value(n)}") + sql.raw("#{self} LIKE #{sql.value(n)}") + end + + def not_like(n) + sql.raw("#{self} NOT LIKE #{sql.value(n)}") + end + + private + + def sql + @sql ||= Rebel::SQLQ end end - @identifier_quote = '"' - @string_quote = "'" - @escaped_string_quote = "''" - - class << self - def identifier_quote=(str) - @identifier_quote = str - end - - def string_quote=(str) - @string_quote = str - end - - def escaped_string_quote=(str) - @escaped_string_quote = str - end - + module SQLB def raw(str) - Raw.new(str) + Raw.new(str).tap { |r| r.instance_variable_set(:@sql, self) } end def create_table(table_name, desc) - raw <<-SQL - CREATE TABLE #{name(table_name)} ( - #{list(desc.map { |k, v| "#{name(k)} #{v}" })} - ) - SQL + raw %[CREATE TABLE #{name(table_name)} (#{list(desc.map { |k, v| "#{name(k)} #{v}" })})] end def drop_table(table_name) - raw <<-SQL - DROP TABLE #{name(table_name)} - SQL + raw "DROP TABLE #{name(table_name)}" end - def select(*fields, from: nil, where: nil, inner: nil, left: nil, right: nil) - raw <<-SQL - SELECT #{names(*fields)} FROM #{name(from)} - #{inner?(inner)} - #{left?(left)} - #{right?(right)} - #{where?(where)} - SQL + def select(*fields, distinct: nil, from: nil, where: nil, inner: nil, left: nil, right: nil, group: nil, order: nil, limit: nil, offset: nil) + raw [ + "SELECT #{distinct ? "DISTINCT #{names(*distinct)}" : names(*fields)}", + from?(from), + inner?(inner), + left?(left), + right?(right), + where?(where), + group?(group), + order?(order), + limit?(limit, offset), + ].compact.join(' ') end def insert_into(table_name, *rows) - raw <<-SQL - INSERT INTO #{name(table_name)} (#{names(*rows.first.keys)}) - VALUES #{list(rows.map { |r| "(#{values(*r.values)})" })} - SQL + raw [ + "INSERT INTO #{name(table_name)} (#{names(*rows.first.keys)})", + "VALUES #{list(rows.map { |r| "(#{values(*r.values)})" })}", + ].join(' ') end def update(table_name, set: nil, where: nil, inner: nil, left: nil, right: nil) raise ArgumentError if set.nil? - raw <<-SQL - UPDATE #{name(table_name)} - SET #{assign_clause(set)} - #{inner?(inner)} - #{left?(left)} - #{right?(right)} - #{where?(where)} - SQL + raw [ + "UPDATE #{name(table_name)}", + "SET #{assign_clause(set)}", + inner?(inner), + left?(left), + right?(right), + where?(where), + ].compact.join(' ') end def delete_from(table_name, where: nil, inner: nil, left: nil, right: nil) - raw <<-SQL - DELETE FROM #{name(table_name)} - #{inner?(inner)} - #{left?(left)} - #{right?(right)} - #{where?(where)} - SQL + raw [ + "DELETE FROM #{name(table_name)}", + inner?(inner), + left?(left), + right?(right), + where?(where), + ].join(' ') end def truncate(table_name) - raw <<-SQL - TRUNCATE #{name(table_name)} - SQL + raw "TRUNCATE #{name(table_name)}" end ## Functions @@ -231,6 +245,10 @@ module Rebel::SQL end alias fn function + def by(*n) + raw("BY #{names(*n)}") + end + def count(*n) raw("COUNT(#{names(*n)})") end @@ -257,9 +275,10 @@ module Rebel::SQL ## Support - def name(name) + def name(name = nil) + super() if name.nil? # workaround for pry and introspection return name if name.is_a?(Raw) - return raw('*') if name == '*' + return raw('*') if name == :* raw(name.to_s.split('.').map { |e| "#{@identifier_quote}#{e}#{@identifier_quote}" }.join('.')) end @@ -273,18 +292,21 @@ module Rebel::SQL end def escape_str(str) - str.tr(@string_quote, @escaped_string_quote) + str.dup.tap do |s| + s.gsub!('\\') { @escaped_string_backslash } if @escaped_string_backslash + s.gsub!(@string_quote) { @escaped_string_quote } + end end def value(v) case v when Raw then v - when String then raw "'#{escape_str(v)}'" + when String then raw "#{@string_quote}#{escape_str(v)}#{@string_quote}" when Integer then raw v.to_s - when TrueClass, FalseClass then raw(v ? 'TRUE' : 'FALSE') + when TrueClass, FalseClass then raw(v ? @true_literal : @false_literal) when Date, Time, DateTime then value(v.iso8601) when nil then raw 'NULL' - else raise NotImplementedError, v.inspect + else raise NotImplementedError, "#{v.class}: #{v.inspect}" end end @@ -312,6 +334,8 @@ module Rebel::SQL case right when Array name(left).in(*right) + when nil + name(left).is(name_or_value(right)) else name(left).eq(name_or_value(right)) end @@ -329,6 +353,10 @@ module Rebel::SQL end.join(' AND ') end + def from?(from) + from ? "FROM #{name(from)}" : nil + end + def where?(*clause) clause.any? ? "WHERE #{and_clause(*clause)}" : nil end @@ -344,5 +372,48 @@ module Rebel::SQL def right?(join) join ? "RIGHT #{join}" : nil end + + def group?(group) + group ? "GROUP #{name(group)}" : nil + end + + def order?(order) + order ? "ORDER #{name(order)}" : nil + end + + def limit?(limit, offset) + limit ? "LIMIT #{value(limit)}" << (offset ? " OFFSET #{offset}" : "") : nil + end end end + +module Rebel + def self.SQL(options = {}, &block) + sql = const_defined?(:SQL) && options.empty? ? SQL : Module.new do + @identifier_quote = options[:identifier_quote] || '"' + @string_quote = options[:string_quote] || "'" + @escaped_string_quote = options[:escaped_string_quote] || "''" + @escaped_string_backslash = options[:escaped_string_backslash] + @true_literal = options[:true_literal] || 'TRUE' + @false_literal = options[:false_literal] || 'FALSE' + + extend Rebel::SQLB + include Rebel::SQLQ + + def self.name(name = nil) + return "Rebel::SQL" if name.nil? + super + end + + def self.inspect + "#" + end + end + + return sql.instance_eval(&block) unless block.nil? + + sql + end + + SQL = SQL() +end diff --git a/rebel.gemspec b/rebel.gemspec index fb81a99..75a3680 100644 --- a/rebel.gemspec +++ b/rebel.gemspec @@ -1,11 +1,11 @@ Gem::Specification.new do |s| s.name = 'rebel' - s.version = '0.3.3' + s.version = '0.7.2' s.licenses = ['MIT'] s.summary = 'Fight against the Object tyranny' s.description = 'SQL-flavoured Ruby, or is it the other way around?' s.authors = ['Loic Nageleisen'] s.email = 'loic.nageleisen@gmail.com' s.files = Dir['lib/**/*.rb'] - s.homepage = 'https://github.com/lloeki/rebel.git' + s.homepage = 'https://gitlab.com/lloeki/rebel.git' end diff --git a/test/test_exec.rb b/test/test_exec.rb index cf7c18c..f9cb146 100644 --- a/test/test_exec.rb +++ b/test/test_exec.rb @@ -44,6 +44,6 @@ class TestExec < Minitest::Test def test_select create_table :foo, id: 'INT', col: 'VARCHAR(255)' insert_into :foo, id: 1, col: 'whatevs' - assert_equal(select('*', from: :foo), [[1, 'whatevs']]) + assert_equal(select(:*, from: :foo), [[1, 'whatevs']]) end end diff --git a/test/test_raw.rb b/test/test_raw.rb index 26ed190..e3cee69 100644 --- a/test/test_raw.rb +++ b/test/test_raw.rb @@ -3,109 +3,244 @@ require 'helper' require 'rebel' class TestRaw < Minitest::Test - def assert_str_equal(expected, actual) - assert_equal(expected.to_s, actual.to_s) + def assert_sql(expected, &actual) + assert_equal(expected.to_s, Rebel::SQL(&actual).to_s) + end + + def assert_mysql(expected, &actual) + assert_equal(expected.to_s, Rebel::SQL(identifier_quote: '`', escaped_string_quote: "\\'", escaped_string_backslash: '\\', &actual).to_s) + end + + def assert_sqlite(expected, &actual) + assert_equal(expected.to_s, Rebel::SQL(true_literal: '1', false_literal: '0', &actual).to_s) + end + + def assert_postgresql(expected, &actual) + assert_equal(expected.to_s, Rebel::SQL(&actual).to_s) end def test_and - assert_str_equal(Rebel::SQL.name(:foo).eq(1).and(Rebel::SQL.name(:bar).eq(2)), '"foo" = 1 AND "bar" = 2') + assert_sql('"foo" = 1 AND "bar" = 2') { name(:foo).eq(1).and(name(:bar).eq(2)) } + assert_sql('"foo" = 1 AND "bar" = 2') { name(:foo).eq(1) & name(:bar).eq(2) } + assert_sql('"foo" = 1 AND "bar" = 2') { (name(:foo) == 1) & (name(:bar) == 2) } end def test_or - assert_str_equal(Rebel::SQL.name(:foo).eq(1).or(Rebel::SQL.name(:bar).eq(2)), '"foo" = 1 OR "bar" = 2') + assert_sql('"foo" = 1 OR "bar" = 2') { name(:foo).eq(1).or(name(:bar).eq(2)) } + assert_sql('"foo" = 1 OR "bar" = 2') { name(:foo).eq(1) | name(:bar).eq(2) } + assert_sql('"foo" = 1 OR "bar" = 2') { (name(:foo) == 1) | (name(:bar) == 2) } end def test_and_or - assert_str_equal(Rebel::SQL.name(:foo).eq(0).and(Rebel::SQL.name(:foo).eq(1).or(Rebel::SQL.name(:bar).eq(2))), '"foo" = 0 AND ("foo" = 1 OR "bar" = 2)') + assert_sql('"foo" = 0 AND ("foo" = 1 OR "bar" = 2)') { name(:foo).eq(0).and(name(:foo).eq(1).or(name(:bar).eq(2))) } + assert_sql('"foo" = 0 AND ("foo" = 1 OR "bar" = 2)') { name(:foo).eq(0) & (name(:foo).eq(1) | name(:bar).eq(2)) } end def test_or_and_or - assert_str_equal(Rebel::SQL.name(:foo).eq(1).or(Rebel::SQL.name(:bar).eq(2)).and(Rebel::SQL.name(:foo).eq(3).or(Rebel::SQL.name(:bar).eq(4))), '("foo" = 1 OR "bar" = 2) AND ("foo" = 3 OR "bar" = 4)') + assert_sql('("foo" = 1 OR "bar" = 2) AND ("foo" = 3 OR "bar" = 4)') { name(:foo).eq(1).or(name(:bar).eq(2)).and(name(:foo).eq(3).or(name(:bar).eq(4))) } + assert_sql('("foo" = 1 OR "bar" = 2) AND ("foo" = 3 OR "bar" = 4)') { (name(:foo).eq(1) | name(:bar).eq(2)) & (name(:foo).eq(3) | name(:bar).eq(4)) } + end + + def test_and_or_and + assert_sql('"foo" = 1 AND "bar" = 2 OR "foo" = 3 AND "bar" = 4') { name(:foo).eq(1).and(name(:bar).eq(2)).or(name(:foo).eq(3).and(name(:bar).eq(4))) } + assert_sql('"foo" = 1 AND "bar" = 2 OR "foo" = 3 AND "bar" = 4') { name(:foo).eq(1) & name(:bar).eq(2) | name(:foo).eq(3) & name(:bar).eq(4) } end def test_is - assert_str_equal(Rebel::SQL.name(:foo).is(nil), '"foo" IS NULL') - assert_str_equal(Rebel::SQL.name(:foo).is(42), '"foo" = 42') - assert_str_equal(Rebel::SQL.name(:foo).is(Rebel::SQL.name(:bar)), '"foo" = "bar"') + assert_sql('"foo" IS NULL') { name(:foo).is(nil) } + assert_sql('"foo" IS 42') { name(:foo).is(42) } + assert_sql('"foo" IS "bar"') { name(:foo).is(name(:bar)) } + end + + def test_is_not + assert_sql('"foo" IS NOT NULL') { name(:foo).is_not(nil) } + assert_sql('"foo" IS NOT 42') { name(:foo).is_not(42) } + assert_sql('"foo" IS NOT "bar"') { name(:foo).is_not(name(:bar)) } end def test_eq - assert_str_equal(Rebel::SQL.name(:foo).eq(nil), '"foo" IS NULL') - assert_str_equal(Rebel::SQL.name(:foo) == nil, '"foo" IS NULL') - assert_str_equal(Rebel::SQL.name(:foo).eq(Rebel::SQL.name(:bar)), '"foo" = "bar"') - assert_str_equal(Rebel::SQL.name(:foo) == Rebel::SQL.name(:bar), '"foo" = "bar"') + assert_sql('"foo" = NULL') { name(:foo).eq(nil) } + assert_sql('"foo" = NULL') { name(:foo) == nil } + assert_sql('"foo" = "bar"') { name(:foo).eq(name(:bar)) } + assert_sql('"foo" = "bar"') { name(:foo) == name(:bar) } end def test_ne - assert_str_equal(Rebel::SQL.name(:foo).ne(Rebel::SQL.name(:bar)), '"foo" != "bar"') - assert_str_equal(Rebel::SQL.name(:foo) != Rebel::SQL.name(:bar), '"foo" != "bar"') - assert_str_equal(Rebel::SQL.name(:foo).ne(nil), '"foo" IS NOT NULL') - assert_str_equal(Rebel::SQL.name(:foo) != nil, '"foo" IS NOT NULL') + assert_sql('"foo" != "bar"') { name(:foo).ne(name(:bar)) } + assert_sql('"foo" != "bar"') { name(:foo) != name(:bar) } + assert_sql('"foo" != NULL') { name(:foo).ne(nil) } + assert_sql('"foo" != NULL') { name(:foo) != nil } end def test_lt - assert_str_equal(Rebel::SQL.name(:foo).lt(Rebel::SQL.name(:bar)), '"foo" < "bar"') - assert_str_equal(Rebel::SQL.name(:foo) < Rebel::SQL.name(:bar), '"foo" < "bar"') + assert_sql('"foo" < "bar"') { name(:foo).lt(name(:bar)) } + assert_sql('"foo" < "bar"') { name(:foo) < name(:bar) } end def test_gt - assert_str_equal(Rebel::SQL.name(:foo).gt(Rebel::SQL.name(:bar)), '"foo" > "bar"') - assert_str_equal(Rebel::SQL.name(:foo) > Rebel::SQL.name(:bar), '"foo" > "bar"') + assert_sql('"foo" > "bar"') { name(:foo).gt(name(:bar)) } + assert_sql('"foo" > "bar"') { name(:foo) > name(:bar) } end def test_le - assert_str_equal(Rebel::SQL.name(:foo).le(Rebel::SQL.name(:bar)), '"foo" <= "bar"') - assert_str_equal(Rebel::SQL.name(:foo) <= Rebel::SQL.name(:bar), '"foo" <= "bar"') + assert_sql('"foo" <= "bar"') { name(:foo).le(name(:bar)) } + assert_sql('"foo" <= "bar"') { name(:foo) <= name(:bar) } end def test_ge - assert_str_equal(Rebel::SQL.name(:foo).ge(Rebel::SQL.name(:bar)), '"foo" >= "bar"') - assert_str_equal(Rebel::SQL.name(:foo) >= Rebel::SQL.name(:bar), '"foo" >= "bar"') + assert_sql('"foo" >= "bar"') { name(:foo).ge(name(:bar)) } + assert_sql('"foo" >= "bar"') { name(:foo) >= name(:bar) } end def test_in - assert_str_equal(Rebel::SQL.name(:foo).in(1, 2, 3), '"foo" IN (1, 2, 3)') + assert_sql('"foo" IN (1, 2, 3)') { name(:foo).in(1, 2, 3) } + end + + def test_not_in + assert_sql('"foo" NOT IN (1, 2, 3)') { name(:foo).not_in(1, 2, 3) } end def test_like - assert_str_equal(Rebel::SQL.name(:foo).like('%bar%'), %("foo" LIKE '%bar%')) + assert_sql(%("foo" LIKE '%bar%')) { name(:foo).like('%bar%') } + end + + def test_not_like + assert_sql(%("foo" NOT LIKE '%bar%')) { name(:foo).not_like('%bar%') } end def test_where - assert_str_equal(Rebel::SQL.where?(foo: 1, bar: 2, baz: 3), 'WHERE "foo" = 1 AND "bar" = 2 AND "baz" = 3') - assert_str_equal(Rebel::SQL.where?(Rebel::SQL.name(:foo).eq(1).or(Rebel::SQL.name(:bar).eq(2)), Rebel::SQL.name(:baz).eq(3)), 'WHERE ("foo" = 1 OR "bar" = 2) AND "baz" = 3') - assert_str_equal(Rebel::SQL.where?(Rebel::SQL.name(:foo).eq(1).or(Rebel::SQL.name(:bar).eq(2))), 'WHERE ("foo" = 1 OR "bar" = 2)') + assert_sql('WHERE "foo" = 1 AND "bar" = 2 AND "baz" = 3') { where?(foo: 1, bar: 2, baz: 3) } + assert_sql('WHERE ("foo" = 1 OR "bar" = 2) AND "baz" = 3') { where?(name(:foo).eq(1).or(name(:bar).eq(2)), name(:baz).eq(3)) } + assert_sql('WHERE ("foo" = 1 OR "bar" = 2)') { where?(name(:foo).eq(1).or(name(:bar).eq(2))) } + assert_sql('WHERE "foo" IS NULL') { where?(foo: nil) } + assert_sql('WHERE "foo" IN (1, 2, 3)') { where?(foo: [1, 2, 3]) } end def test_join - assert_str_equal(Rebel::SQL.join(:foo), 'JOIN "foo"') + assert_sql('JOIN "foo"') { join(:foo) } end def test_function - assert_str_equal(Rebel::SQL.function('COALESCE', :foo, 0), 'COALESCE("foo", 0)') + assert_sql('COALESCE("foo", 0)') { function('COALESCE', :foo, 0) } end def test_where_function - assert_str_equal(Rebel::SQL.where?(Rebel::SQL.function('COALESCE', :foo, 0).eq 42), 'WHERE COALESCE("foo", 0) = 42') + assert_sql('WHERE COALESCE("foo", 0) = 42') { where?(function('COALESCE', :foo, 0).eq 42) } + end + + def test_name + assert_sql('"foo"') { name(:foo) } + assert_mysql('`foo`') { name(:foo) } + assert_postgresql('"foo"') { name(:foo) } + assert_sqlite('"foo"') { name(:foo) } + end + + def test_string + assert_sql("'FOO'") { value('FOO') } + assert_mysql("'FOO'") { value('FOO') } + assert_postgresql("'FOO'") { value('FOO') } + assert_sqlite("'FOO'") { value('FOO') } + end + + def test_escaped_string + assert_sql (%q('FOO''BAR')) { value(%q(FOO'BAR)) } + assert_postgresql (%q('FOO''BAR')) { value(%q(FOO'BAR)) } + assert_sqlite (%q('FOO''BAR')) { value(%q(FOO'BAR)) } + assert_mysql (%q('FOO\'BAR')) { value(%q(FOO'BAR)) } + + assert_sql (%q('FOO"BAR')) { value(%q(FOO"BAR)) } + assert_postgresql (%q('FOO"BAR')) { value(%q(FOO"BAR)) } + assert_sqlite (%q('FOO"BAR')) { value(%q(FOO"BAR)) } + assert_mysql (%q('FOO"BAR')) { value(%q(FOO"BAR)) } + + assert_sql (%q('FOO\BAR')) { value(%q(FOO\BAR)) } + assert_postgresql (%q('FOO\BAR')) { value(%q(FOO\BAR)) } + assert_sqlite (%q('FOO\BAR')) { value(%q(FOO\BAR)) } + assert_mysql (%q('FOO\\BAR')) { value(%q(FOO\BAR)) } + + assert_sql (%q('FOO\\''BAR')) { value(%q(FOO\'BAR)) } + assert_postgresql (%q('FOO\\''BAR')) { value(%q(FOO\'BAR)) } + assert_sqlite (%q('FOO\\''BAR')) { value(%q(FOO\'BAR)) } + assert_mysql (%q('FOO\\\'BAR')) { value(%q(FOO\'BAR)) } + end + + def test_boolean_literal + assert_sql('TRUE') { value(true) } + assert_mysql('TRUE') { value(true) } + assert_postgresql('TRUE') { value(true) } + assert_sqlite('1') { value(true) } + + assert_sql('FALSE') { value(false) } + assert_mysql('FALSE') { value(false) } + assert_postgresql('FALSE') { value(false) } + assert_sqlite('0') { value(false) } end def test_value - assert_str_equal(Rebel::SQL.value(Rebel::SQL.raw("'FOO'")), "'FOO'") - assert_str_equal(Rebel::SQL.value('FOO'), "'FOO'") - assert_str_equal(Rebel::SQL.value(1), '1') - assert_str_equal(Rebel::SQL.value(true), 'TRUE') - assert_str_equal(Rebel::SQL.value(false), 'FALSE') - assert_str_equal(Rebel::SQL.value(Date.new(2016, 12, 31)), "'2016-12-31'") - assert_str_equal(Rebel::SQL.value(Time.utc(2016, 12, 31, 23, 59, 59)), "'2016-12-31T23:59:59Z'") - assert_str_equal(Rebel::SQL.value(DateTime.new(2016, 12, 31, 23, 59, 59)), "'2016-12-31T23:59:59+00:00'") - assert_str_equal(Rebel::SQL.value(nil), 'NULL') + assert_sql("'FOO'") { value(raw("'FOO'")) } + assert_sql("'FOO'") { value('FOO') } + assert_sql('1') { value(1) } + assert_sql('TRUE') { value(true) } + assert_sql('FALSE') { value(false) } + assert_sql("'2016-12-31'") { value(Date.new(2016, 12, 31)) } + assert_sql("'2016-12-31T23:59:59Z'") { value(Time.utc(2016, 12, 31, 23, 59, 59)) } + assert_sql("'2016-12-31T23:59:59+00:00'") { value(DateTime.new(2016, 12, 31, 23, 59, 59)) } + assert_sql('NULL') { value(nil) } end def test_select - assert_str_equal(Rebel::SQL.select(Rebel::SQL.raw('*'), from: Rebel::SQL.name(:foo)).gsub(/\s+/, ' ').strip, 'SELECT * FROM "foo"') + assert_sql('SELECT * FROM "foo"') { select(raw('*'), from: name(:foo)) } + end + + def test_select_without_from + assert_sql('SELECT 1') { select(raw('1')).strip } + end + + def test_select_distinct + assert_sql('SELECT DISTINCT "bar" FROM "foo"') { select(distinct: :bar, from: :foo) } + end + + def test_select_distinct_multiple + assert_sql('SELECT DISTINCT "bar", "baz" FROM "foo"') { select(distinct: [:bar, :baz], from: :foo) } + end + + def test_select_group_by + assert_sql('SELECT "bar" FROM "foo" GROUP BY "baz"') { select(:bar, from: :foo, group: by(:baz)) } + end + + def test_select_group_by_having + assert_sql('SELECT "bar" FROM "foo" GROUP BY "baz" HAVING COUNT("qux") > 5') { select(:bar, from: :foo, group: by(:baz).having(count(:qux).gt(5))) } + end + + def test_select_order_by + assert_sql('SELECT "bar" FROM "foo" ORDER BY "baz"') { select(:bar, from: :foo, order: by(:baz)) } + end + + def test_select_order_by_asc + assert_sql('SELECT "bar" FROM "foo" ORDER BY "baz" ASC') { select(:bar, from: :foo, order: by(:baz).asc) } + end + + def test_select_order_by_desc + assert_sql('SELECT "bar" FROM "foo" ORDER BY "baz" DESC') { select(:bar, from: :foo, order: by(:baz).desc) } + end + + def test_select_multiple_order_by + assert_sql('SELECT "bar" FROM "foo" ORDER BY "baz", "qux"') { select(:bar, from: :foo, order: by(:baz, :qux)) } + end + + def test_select_multiple_order_by_opposing + assert_sql('SELECT "bar" FROM "foo" ORDER BY "baz" ASC, "qux" DESC') { select(:bar, from: :foo, order: by(name(:baz).asc, name(:qux).desc)) } + end + + def test_select_limit + assert_sql('SELECT "bar" FROM "foo" LIMIT 10') { select(:bar, from: :foo, limit: 10) } + end + + def test_select_offset + assert_sql('SELECT "bar" FROM "foo" LIMIT 10 OFFSET 20') { select(:bar, from: :foo, limit: 10, offset: 20) } end def test_nested_select - assert_str_equal(Rebel::SQL.select(Rebel::SQL.raw('*'), from: Rebel::SQL.name(:foo), where: Rebel::SQL.name(:bar).in(Rebel::SQL.select(Rebel::SQL.name(:bar), from: Rebel::SQL.name(:foo)))).gsub(/\s+/, ' ').strip, 'SELECT * FROM "foo" WHERE "bar" IN ( SELECT "bar" FROM "foo" )') + assert_sql('SELECT * FROM "foo" WHERE "bar" IN (SELECT "bar" FROM "foo")') { select(raw('*'), from: name(:foo), where: name(:bar).in(select(name(:bar), from: name(:foo)))) } end end