2014-08-26 17:16:46 +02:00
module . exports = function ( qb , clientName , aliasName ) {
2013-12-27 14:44:21 -05:00
2014-04-08 16:25:57 -04:00
var Raw = require ( '../../../lib/raw' ) ;
2013-12-27 14:44:21 -05:00
2014-08-26 17:16:46 +02:00
function verifySqlResult ( expectedObj , sqlObj ) {
Object . keys ( expectedObj ) . forEach ( function ( key ) {
if ( typeof expectedObj [ key ] === 'function' ) {
expectedObj [ key ] ( sqlObj [ key ] ) ;
} else {
expect ( sqlObj [ key ] ) . to . deep . equal ( expectedObj [ key ] ) ;
}
} ) ;
}
function testsql ( func , res ) {
var sqlRes = func . toSQL ( ) ;
var checkValue = res [ clientName ] || res [ aliasName ] || res [ 'default' ] ;
if ( ! checkValue ) {
throw new Error ( "Missing test value for name \"" + clientName + "\" or it's alias \"" + aliasName + "\" or for \"default\"" ) ;
}
if ( typeof res === 'function' ) {
res ( sqlRes ) ;
} else {
if ( typeof checkValue === 'string' ) {
verifySqlResult ( {
sql : checkValue
} , sqlRes ) ;
} else {
verifySqlResult ( checkValue , sqlRes ) ;
}
}
}
2013-12-27 14:44:21 -05:00
2014-08-26 17:16:46 +02:00
function testquery ( func , res ) {
var queryRes = func . toQuery ( ) ;
var checkValue = res [ clientName ] || res [ aliasName ] || res [ 'default' ] ;
2013-12-27 14:44:21 -05:00
2014-08-26 17:16:46 +02:00
if ( ! checkValue ) {
throw new Error ( "Missing test value for name \"" + clientName + "\" or it's alias \"" + aliasName + "\" or for \"default\"" ) ;
}
if ( typeof res === 'function' ) {
res ( queryRes ) ;
} else {
expect ( queryRes ) . to . deep . equal ( checkValue ) ;
}
}
describe ( "QueryBuilder " + clientName , function ( ) {
2014-04-08 16:25:57 -04:00
var raw = function ( sql , bindings ) { return new Raw ( sql , bindings ) ; } ;
2013-12-27 14:44:21 -05:00
it ( "basic select" , function ( ) {
2014-08-26 17:16:46 +02:00
testsql ( qb ( ) . select ( '*' ) . from ( 'users' ) , {
mysql : 'select * from `users`' ,
default : 'select * from "users"' ,
} ) ;
2013-12-27 14:44:21 -05:00
} ) ;
it ( "adding selects" , function ( ) {
2014-08-26 17:16:46 +02:00
testsql ( qb ( ) . select ( 'foo' ) . select ( 'bar' ) . select ( [ 'baz' , 'boom' ] ) . from ( 'users' ) , {
mysql : 'select `foo`, `bar`, `baz`, `boom` from `users`' ,
default : 'select "foo", "bar", "baz", "boom" from "users"'
} ) ;
2013-12-27 14:44:21 -05:00
} ) ;
it ( "basic select distinct" , function ( ) {
2014-08-26 17:16:46 +02:00
testsql ( qb ( ) . distinct ( ) . select ( 'foo' , 'bar' ) . from ( 'users' ) , {
mysql : { sql : 'select distinct `foo`, `bar` from `users`' } ,
default : { sql : 'select distinct "foo", "bar" from "users"' }
} ) ;
2013-12-27 14:44:21 -05:00
} ) ;
it ( "basic alias" , function ( ) {
2014-08-26 17:16:46 +02:00
testsql ( qb ( ) . select ( 'foo as bar' ) . from ( 'users' ) , {
mysql : 'select `foo` as `bar` from `users`' ,
oracle : 'select "foo" "bar" from "users"' ,
default : 'select "foo" as "bar" from "users"'
} ) ;
2014-08-11 12:25:39 +02:00
} ) ;
2014-08-26 17:16:46 +02:00
it ( "basic alias trims spaces" , function ( ) {
testsql ( qb ( ) . select ( ' foo as bar ' ) . from ( 'users' ) , {
mysql : 'select `foo` as `bar` from `users`' ,
oracle : 'select "foo" "bar" from "users"' ,
default : 'select "foo" as "bar" from "users"'
} ) ;
2014-07-14 15:19:03 -04:00
} ) ;
it ( "allows for case-insensitive alias" , function ( ) {
2014-08-26 17:16:46 +02:00
testsql ( qb ( ) . select ( ' foo aS bar ' ) . from ( 'users' ) , {
mysql : 'select `foo` as `bar` from `users`' ,
oracle : 'select "foo" "bar" from "users"' ,
default : 'select "foo" as "bar" from "users"'
} ) ;
2014-08-11 12:25:39 +02:00
} ) ;
2013-12-27 14:44:21 -05:00
it ( "basic table wrapping" , function ( ) {
2014-08-26 17:16:46 +02:00
testsql ( qb ( ) . select ( '*' ) . from ( 'public.users' ) , {
mysql : 'select * from `public`.`users`' ,
default : 'select * from "public"."users"'
} ) ;
2013-12-27 14:44:21 -05:00
} ) ;
it ( "basic wheres" , function ( ) {
2014-08-26 17:16:46 +02:00
testsql ( qb ( ) . select ( '*' ) . from ( 'users' ) . where ( 'id' , '=' , 1 ) , {
mysql : {
sql : 'select * from `users` where `id` = ?' ,
bindings : [ 1 ]
} ,
default : {
sql : 'select * from "users" where "id" = ?' ,
bindings : [ 1 ]
}
} ) ;
testquery ( qb ( ) . select ( '*' ) . from ( 'users' ) . where ( 'id' , '=' , 1 ) , {
mysql : 'select * from `users` where `id` = 1' ,
postgres : 'select * from "users" where "id" = \'1\'' ,
default : 'select * from "users" where "id" = 1'
} ) ;
2013-12-27 14:44:21 -05:00
} ) ;
it ( "where betweens" , function ( ) {
2014-08-26 17:16:46 +02:00
testsql ( qb ( ) . select ( '*' ) . from ( 'users' ) . whereBetween ( 'id' , [ 1 , 2 ] ) , {
mysql : {
sql : 'select * from `users` where `id` between ? and ?' ,
bindings : [ 1 , 2 ]
} ,
default : {
sql : 'select * from "users" where "id" between ? and ?' ,
bindings : [ 1 , 2 ]
}
} ) ;
2014-02-22 17:06:33 -05:00
} ) ;
2013-12-27 14:44:21 -05:00
2014-05-09 14:42:29 -04:00
it ( "where betweens, alternate" , function ( ) {
2014-08-26 17:16:46 +02:00
testsql ( qb ( ) . select ( '*' ) . from ( 'users' ) . where ( 'id' , 'BeTween' , [ 1 , 2 ] ) , {
mysql : {
sql : 'select * from `users` where `id` between ? and ?' ,
bindings : [ 1 , 2 ]
} ,
default : {
sql : 'select * from "users" where "id" between ? and ?' ,
bindings : [ 1 , 2 ]
}
} ) ;
2014-05-09 14:42:29 -04:00
} ) ;
2014-02-22 17:06:33 -05:00
it ( "where not between" , function ( ) {
2014-08-26 17:16:46 +02:00
testsql ( qb ( ) . select ( '*' ) . from ( 'users' ) . whereNotBetween ( 'id' , [ 1 , 2 ] ) , {
mysql : {
sql : 'select * from `users` where `id` not between ? and ?' ,
bindings : [ 1 , 2 ]
} ,
default : {
sql : 'select * from "users" where "id" not between ? and ?' ,
bindings : [ 1 , 2 ]
}
} ) ;
2013-12-27 14:44:21 -05:00
} ) ;
2014-05-09 14:42:29 -04:00
it ( "where not between, alternate" , function ( ) {
2014-08-26 17:16:46 +02:00
testsql ( qb ( ) . select ( '*' ) . from ( 'users' ) . where ( 'id' , 'not between ' , [ 1 , 2 ] ) , {
mysql : {
sql : 'select * from `users` where `id` not between ? and ?' ,
bindings : [ 1 , 2 ]
} ,
default : {
sql : 'select * from "users" where "id" not between ? and ?' ,
bindings : [ 1 , 2 ]
}
} ) ;
2014-05-09 14:42:29 -04:00
} ) ;
2013-12-27 14:44:21 -05:00
it ( "basic or wheres" , function ( ) {
2014-08-26 17:16:46 +02:00
testsql ( qb ( ) . select ( '*' ) . from ( 'users' ) . where ( 'id' , '=' , 1 ) . orWhere ( 'email' , '=' , 'foo' ) , {
mysql : {
sql : 'select * from `users` where `id` = ? or `email` = ?' ,
bindings : [ 1 , 'foo' ]
} ,
default : {
sql : 'select * from "users" where "id" = ? or "email" = ?' ,
bindings : [ 1 , 'foo' ]
}
} ) ;
2013-12-27 14:44:21 -05:00
} ) ;
2014-07-01 08:53:35 -04:00
it ( "chained or wheres" , function ( ) {
2014-08-26 17:16:46 +02:00
testsql ( qb ( ) . select ( '*' ) . from ( 'users' ) . where ( 'id' , '=' , 1 ) . or . where ( 'email' , '=' , 'foo' ) , {
mysql : {
sql : 'select * from `users` where `id` = ? or `email` = ?' ,
bindings : [ 1 , 'foo' ]
} ,
default : {
sql : 'select * from "users" where "id" = ? or "email" = ?' ,
bindings : [ 1 , 'foo' ]
}
} ) ;
2014-07-01 08:53:35 -04:00
} ) ;
2013-12-27 14:44:21 -05:00
it ( "raw wheres" , function ( ) {
2014-08-26 17:16:46 +02:00
testsql ( qb ( ) . select ( '*' ) . from ( 'users' ) . where ( raw ( 'id = ? or email = ?' , [ 1 , 'foo' ] ) ) , {
mysql : {
sql : 'select * from `users` where id = ? or email = ?' ,
bindings : [ 1 , 'foo' ]
} ,
default : {
sql : 'select * from "users" where id = ? or email = ?' ,
bindings : [ 1 , 'foo' ]
}
} ) ;
2013-12-27 14:44:21 -05:00
} ) ;
it ( "raw or wheres" , function ( ) {
2014-08-26 17:16:46 +02:00
testsql ( qb ( ) . select ( '*' ) . from ( 'users' ) . where ( 'id' , '=' , 1 ) . orWhere ( raw ( 'email = ?' , [ 'foo' ] ) ) , {
mysql : {
sql : 'select * from `users` where `id` = ? or email = ?' ,
bindings : [ 1 , 'foo' ]
} ,
default : {
sql : 'select * from "users" where "id" = ? or email = ?' ,
bindings : [ 1 , 'foo' ]
}
} ) ;
2013-12-27 14:44:21 -05:00
} ) ;
2014-07-01 08:53:35 -04:00
it ( "chained raw or wheres" , function ( ) {
2014-08-26 17:16:46 +02:00
testsql ( qb ( ) . select ( '*' ) . from ( 'users' ) . where ( 'id' , '=' , 1 ) . or . where ( raw ( 'email = ?' , [ 'foo' ] ) ) , {
mysql : {
sql : 'select * from `users` where `id` = ? or email = ?' ,
bindings : [ 1 , 'foo' ]
} ,
default : {
sql : 'select * from "users" where "id" = ? or email = ?' ,
bindings : [ 1 , 'foo' ]
}
} ) ;
2014-07-01 08:53:35 -04:00
} ) ;
2013-12-27 14:44:21 -05:00
it ( "basic where ins" , function ( ) {
2014-08-26 17:16:46 +02:00
testsql ( qb ( ) . select ( '*' ) . from ( 'users' ) . whereIn ( 'id' , [ 1 , 2 , 3 ] ) , {
mysql : {
sql : 'select * from `users` where `id` in (?, ?, ?)' ,
bindings : [ 1 , 2 , 3 ]
} ,
default : {
sql : 'select * from "users" where "id" in (?, ?, ?)' ,
bindings : [ 1 , 2 , 3 ]
}
} ) ;
2014-02-22 17:06:33 -05:00
} ) ;
2013-12-27 14:44:21 -05:00
2014-02-22 17:06:33 -05:00
it ( "orWhereIn" , function ( ) {
2014-08-26 17:16:46 +02:00
testsql ( qb ( ) . select ( '*' ) . from ( 'users' ) . where ( 'id' , '=' , 1 ) . orWhereIn ( 'id' , [ 1 , 2 , 3 ] ) , {
mysql : {
sql : 'select * from `users` where `id` = ? or `id` in (?, ?, ?)' ,
bindings : [ 1 , 1 , 2 , 3 ]
} ,
default : {
sql : 'select * from "users" where "id" = ? or "id" in (?, ?, ?)' ,
bindings : [ 1 , 1 , 2 , 3 ]
}
} ) ;
2013-12-27 14:44:21 -05:00
} ) ;
it ( "basic where not ins" , function ( ) {
2014-08-26 17:16:46 +02:00
testsql ( qb ( ) . select ( '*' ) . from ( 'users' ) . whereNotIn ( 'id' , [ 1 , 2 , 3 ] ) , {
mysql : {
sql : 'select * from `users` where `id` not in (?, ?, ?)' ,
bindings : [ 1 , 2 , 3 ]
} ,
default : {
sql : 'select * from "users" where "id" not in (?, ?, ?)' ,
bindings : [ 1 , 2 , 3 ]
}
} ) ;
2014-02-22 17:06:33 -05:00
} ) ;
2013-12-27 14:44:21 -05:00
2014-07-01 08:53:35 -04:00
it ( "chained or where not in" , function ( ) {
2014-08-26 17:16:46 +02:00
testsql ( qb ( ) . select ( '*' ) . from ( 'users' ) . where ( 'id' , '=' , 1 ) . or . not . whereIn ( 'id' , [ 1 , 2 , 3 ] ) , {
mysql : {
sql : 'select * from `users` where `id` = ? or `id` not in (?, ?, ?)' ,
bindings : [ 1 , 1 , 2 , 3 ]
} ,
default : {
sql : 'select * from "users" where "id" = ? or "id" not in (?, ?, ?)' ,
bindings : [ 1 , 1 , 2 , 3 ]
}
} ) ;
2014-07-01 08:53:35 -04:00
} ) ;
it ( "or.whereIn" , function ( ) {
2014-08-26 17:16:46 +02:00
testsql ( qb ( ) . select ( '*' ) . from ( 'users' ) . where ( 'id' , '=' , 1 ) . or . whereIn ( 'id' , [ 4 , 2 , 3 ] ) , {
mysql : {
sql : 'select * from `users` where `id` = ? or `id` in (?, ?, ?)' ,
bindings : [ 1 , 4 , 2 , 3 ]
} ,
default : {
sql : 'select * from "users" where "id" = ? or "id" in (?, ?, ?)' ,
bindings : [ 1 , 4 , 2 , 3 ]
}
} ) ;
2014-07-01 08:53:35 -04:00
} ) ;
it ( "chained basic where not ins" , function ( ) {
2014-08-26 17:16:46 +02:00
testsql ( qb ( ) . select ( '*' ) . from ( 'users' ) . not . whereIn ( 'id' , [ 1 , 2 , 3 ] ) , {
mysql : {
sql : 'select * from `users` where `id` not in (?, ?, ?)' ,
bindings : [ 1 , 2 , 3 ]
} ,
default : {
sql : 'select * from "users" where "id" not in (?, ?, ?)' ,
bindings : [ 1 , 2 , 3 ]
}
} ) ;
2014-07-01 08:53:35 -04:00
} ) ;
it ( "chained or where not in" , function ( ) {
2014-08-26 17:16:46 +02:00
testsql ( qb ( ) . select ( '*' ) . from ( 'users' ) . where ( 'id' , '=' , 1 ) . or . not . whereIn ( 'id' , [ 1 , 2 , 3 ] ) , {
mysql : {
sql : 'select * from `users` where `id` = ? or `id` not in (?, ?, ?)' ,
bindings : [ 1 , 1 , 2 , 3 ]
} ,
default : {
sql : 'select * from "users" where "id" = ? or "id" not in (?, ?, ?)' ,
bindings : [ 1 , 1 , 2 , 3 ]
}
} ) ;
2013-12-27 14:44:21 -05:00
} ) ;
it ( 'should allow a function as the first argument, for a grouped where clause' , function ( ) {
2014-08-26 17:16:46 +02:00
var partial = qb ( ) . table ( 'test' ) . where ( 'id' , '=' , 1 ) ;
testsql ( partial , {
mysql : 'select * from `test` where `id` = ?' ,
default : 'select * from "test" where "id" = ?'
} ) ;
2013-12-27 14:44:21 -05:00
2014-08-26 17:16:46 +02:00
var subWhere = function ( sql ) {
expect ( this ) . to . equal ( sql ) ;
2013-12-27 14:44:21 -05:00
this . where ( { id : 3 } ) . orWhere ( 'id' , 4 ) ;
} ;
2014-08-26 17:16:46 +02:00
testsql ( partial . where ( subWhere ) , {
mysql : {
sql : 'select * from `test` where `id` = ? and (`id` = ? or `id` = ?)' ,
bindings : [ 1 , 3 , 4 ]
} ,
default : {
sql : 'select * from "test" where "id" = ? and ("id" = ? or "id" = ?)' ,
bindings : [ 1 , 3 , 4 ]
}
} ) ;
2013-12-27 14:44:21 -05:00
} ) ;
it ( 'should accept a function as the "value", for a sub select' , function ( ) {
2014-08-26 17:16:46 +02:00
var chain = qb ( ) . where ( 'id' , '=' , function ( qb ) {
2013-12-27 14:44:21 -05:00
expect ( this ) . to . equal ( qb ) ;
this . select ( 'account_id' ) . from ( 'names' ) . where ( 'names.id' , '>' , 1 ) . orWhere ( function ( ) {
this . where ( 'names.first_name' , 'like' , 'Tim%' ) . andWhere ( 'names.id' , '>' , 10 ) ;
} ) ;
} ) ;
2014-08-26 17:16:46 +02:00
testsql ( chain , {
mysql : {
sql : 'select * where `id` = (select `account_id` from `names` where `names`.`id` > ? or (`names`.`first_name` like ? and `names`.`id` > ?))' ,
bindings : [ 1 , 'Tim%' , 10 ]
} ,
default : {
sql : 'select * where "id" = (select "account_id" from "names" where "names"."id" > ? or ("names"."first_name" like ? and "names"."id" > ?))' ,
bindings : [ 1 , 'Tim%' , 10 ]
}
} ) ;
testquery ( chain , {
mysql : 'select * where `id` = (select `account_id` from `names` where `names`.`id` > 1 or (`names`.`first_name` like \'Tim%\' and `names`.`id` > 10))' ,
postgres : 'select * where "id" = (select "account_id" from "names" where "names"."id" > \'1\' or ("names"."first_name" like \'Tim%\' and "names"."id" > \'10\'))' ,
default : 'select * where "id" = (select "account_id" from "names" where "names"."id" > 1 or ("names"."first_name" like \'Tim%\' and "names"."id" > 10))'
} ) ;
2014-07-01 08:53:35 -04:00
} ) ;
it ( 'should accept a function as the "value", for a sub select when chained' , function ( ) {
2014-08-26 17:16:46 +02:00
var chain = qb ( ) . where ( 'id' , '=' , function ( qb ) {
2014-07-01 08:53:35 -04:00
expect ( this ) . to . equal ( qb ) ;
this . select ( 'account_id' ) . from ( 'names' ) . where ( 'names.id' , '>' , 1 ) . or . where ( function ( ) {
this . where ( 'names.first_name' , 'like' , 'Tim%' ) . and . where ( 'names.id' , '>' , 10 ) ;
} ) ;
} ) ;
2014-08-26 17:16:46 +02:00
testsql ( chain , {
mysql : {
sql : 'select * where `id` = (select `account_id` from `names` where `names`.`id` > ? or (`names`.`first_name` like ? and `names`.`id` > ?))' ,
bindings : [ 1 , 'Tim%' , 10 ]
} ,
default : {
sql : 'select * where "id" = (select "account_id" from "names" where "names"."id" > ? or ("names"."first_name" like ? and "names"."id" > ?))' ,
bindings : [ 1 , 'Tim%' , 10 ]
}
} ) ;
2013-12-27 14:44:21 -05:00
} ) ;
it ( 'should not do whereNull on where("foo", "<>", null) #76' , function ( ) {
2014-08-26 17:16:46 +02:00
testquery ( qb ( ) . where ( 'foo' , '<>' , null ) , {
mysql : 'select * where `foo` <> NULL' ,
default : 'select * where "foo" <> NULL'
} ) ;
2013-12-27 14:44:21 -05:00
} ) ;
it ( 'should expand where("foo", "!=") to - where id = "!="' , function ( ) {
2014-08-26 17:16:46 +02:00
testquery ( qb ( ) . where ( 'foo' , '!=' ) , {
mysql : 'select * where `foo` = \'!=\'' ,
default : 'select * where "foo" = \'!=\''
} ) ;
2013-12-27 14:44:21 -05:00
} ) ;
it ( "unions" , function ( ) {
2014-08-26 17:16:46 +02:00
var chain = qb ( ) . select ( '*' ) . from ( 'users' ) . where ( 'id' , '=' , 1 ) . union ( function ( ) {
2014-02-22 17:06:33 -05:00
this . select ( '*' ) . from ( 'users' ) . where ( 'id' , '=' , 2 ) ;
2014-08-26 17:16:46 +02:00
} ) ;
testsql ( chain , {
mysql : {
sql : 'select * from `users` where `id` = ? union select * from `users` where `id` = ?' ,
bindings : [ 1 , 2 ]
} ,
default : {
sql : 'select * from "users" where "id" = ? union select * from "users" where "id" = ?' ,
bindings : [ 1 , 2 ]
}
} ) ;
2014-02-22 17:06:33 -05:00
} ) ;
2013-12-27 14:44:21 -05:00
2014-04-15 11:43:47 -04:00
// it("handles grouped mysql unions", function() {
2014-08-26 17:16:46 +02:00
// chain = myqb().union(
// raw(myqb().select('*').from('users').where('id', '=', 1)).wrap('(', ')'),
// raw(myqb().select('*').from('users').where('id', '=', 2)).wrap('(', ')')
2014-04-15 11:43:47 -04:00
// ).orderBy('id').limit(10).toSQL();
// expect(chain.sql).to.equal('(select * from `users` where `id` = ?) union (select * from `users` where `id` = ?) order by `id` asc limit ?');
// expect(chain.bindings).to.eql([1, 2, 10]);
// });
2013-12-27 14:44:21 -05:00
it ( "union alls" , function ( ) {
2014-08-26 17:16:46 +02:00
var chain = qb ( ) . select ( '*' ) . from ( 'users' ) . where ( 'id' , '=' , 1 ) . unionAll ( function ( ) {
2014-02-22 17:06:33 -05:00
this . select ( '*' ) . from ( 'users' ) . where ( 'id' , '=' , 2 ) ;
2014-08-26 17:16:46 +02:00
} ) ;
testsql ( chain , {
mysql : {
sql : 'select * from `users` where `id` = ? union all select * from `users` where `id` = ?' ,
bindings : [ 1 , 2 ]
} ,
default : {
sql : 'select * from "users" where "id" = ? union all select * from "users" where "id" = ?' ,
bindings : [ 1 , 2 ]
}
} ) ;
2013-12-27 14:44:21 -05:00
} ) ;
it ( "multiple unions" , function ( ) {
2014-08-26 17:16:46 +02:00
var chain = qb ( ) . select ( '*' ) . from ( 'users' ) . where ( 'id' , '=' , 1 )
. union ( qb ( ) . select ( '*' ) . from ( 'users' ) . where ( 'id' , '=' , 2 ) )
. union ( qb ( ) . select ( '*' ) . from ( 'users' ) . where ( 'id' , '=' , 3 ) ) ;
testsql ( chain , {
mysql : {
sql : 'select * from `users` where `id` = ? union select * from `users` where `id` = ? union select * from `users` where `id` = ?' ,
bindings : [ 1 , 2 , 3 ]
} ,
default : {
sql : 'select * from "users" where "id" = ? union select * from "users" where "id" = ? union select * from "users" where "id" = ?' ,
bindings : [ 1 , 2 , 3 ]
}
} ) ;
2013-12-27 14:44:21 -05:00
} ) ;
it ( "multiple union alls" , function ( ) {
2014-08-26 17:16:46 +02:00
var chain = qb ( ) . select ( '*' ) . from ( 'users' ) . where ( 'id' , '=' , 1 )
. unionAll ( qb ( ) . select ( '*' ) . from ( 'users' ) . where ( 'id' , '=' , 2 ) )
. unionAll ( qb ( ) . select ( '*' ) . from ( 'users' ) . where ( 'id' , '=' , 3 ) ) ;
testsql ( chain , {
mysql : {
sql : 'select * from `users` where `id` = ? union all select * from `users` where `id` = ? union all select * from `users` where `id` = ?' ,
bindings : [ 1 , 2 , 3 ]
} ,
default : {
sql : 'select * from "users" where "id" = ? union all select * from "users" where "id" = ? union all select * from "users" where "id" = ?' ,
bindings : [ 1 , 2 , 3 ]
}
} ) ;
2013-12-27 14:44:21 -05:00
} ) ;
it ( "sub select where ins" , function ( ) {
2014-08-26 17:16:46 +02:00
testsql ( qb ( ) . select ( '*' ) . from ( 'users' ) . whereIn ( 'id' , function ( qb ) {
2013-12-27 14:44:21 -05:00
qb . select ( 'id' ) . from ( 'users' ) . where ( 'age' , '>' , 25 ) . limit ( 3 ) ;
2014-08-26 17:16:46 +02:00
} ) , {
mysql : {
sql : 'select * from `users` where `id` in (select `id` from `users` where `age` > ? limit ?)' ,
bindings : [ 25 , 3 ]
} ,
oracle : {
sql : 'select * from "users" where "id" in (select * from (select "id" from "users" where "age" > ?) where rownum <= ?)' ,
bindings : [ 25 , 3 ]
} ,
default : {
sql : 'select * from "users" where "id" in (select "id" from "users" where "age" > ? limit ?)' ,
bindings : [ 25 , 3 ]
}
} ) ;
2014-02-22 17:06:33 -05:00
} ) ;
2013-12-27 14:44:21 -05:00
2014-02-22 17:06:33 -05:00
it ( "sub select where not ins" , function ( ) {
2014-08-26 17:16:46 +02:00
testsql ( qb ( ) . select ( '*' ) . from ( 'users' ) . whereNotIn ( 'id' , function ( qb ) {
qb . select ( 'id' ) . from ( 'users' ) . where ( 'age' , '>' , 25 ) ;
} ) , {
mysql : {
sql : 'select * from `users` where `id` not in (select `id` from `users` where `age` > ?)' ,
bindings : [ 25 ]
} ,
default : {
sql : 'select * from "users" where "id" not in (select "id" from "users" where "age" > ?)' ,
bindings : [ 25 ]
}
} ) ;
2013-12-27 14:44:21 -05:00
} ) ;
it ( "basic where nulls" , function ( ) {
2014-08-26 17:16:46 +02:00
testsql ( qb ( ) . select ( '*' ) . from ( 'users' ) . whereNull ( 'id' ) , {
mysql : {
sql : 'select * from `users` where `id` is null' ,
bindings : [ ]
} ,
default : {
sql : 'select * from "users" where "id" is null' ,
bindings : [ ]
}
} ) ;
2014-02-22 17:06:33 -05:00
} ) ;
2013-12-27 14:44:21 -05:00
2014-02-22 17:06:33 -05:00
it ( "basic or where nulls" , function ( ) {
2014-08-26 17:16:46 +02:00
testsql ( qb ( ) . select ( '*' ) . from ( 'users' ) . where ( 'id' , '=' , 1 ) . orWhereNull ( 'id' ) , {
mysql : {
sql : 'select * from `users` where `id` = ? or `id` is null' ,
bindings : [ 1 ]
} ,
default : {
sql : 'select * from "users" where "id" = ? or "id" is null' ,
bindings : [ 1 ]
}
} ) ;
2013-12-27 14:44:21 -05:00
} ) ;
it ( "basic where not nulls" , function ( ) {
2014-08-26 17:16:46 +02:00
testsql ( qb ( ) . select ( '*' ) . from ( 'users' ) . whereNotNull ( 'id' ) , {
mysql : {
sql : 'select * from `users` where `id` is not null' ,
bindings : [ ]
} ,
default : {
sql : 'select * from "users" where "id" is not null' ,
bindings : [ ]
}
} ) ;
2014-02-22 17:06:33 -05:00
} ) ;
2013-12-27 14:44:21 -05:00
2014-02-22 17:06:33 -05:00
it ( "basic or where not nulls" , function ( ) {
2014-08-26 17:16:46 +02:00
testsql ( qb ( ) . select ( '*' ) . from ( 'users' ) . where ( 'id' , '>' , 1 ) . orWhereNotNull ( 'id' ) , {
mysql : {
sql : 'select * from `users` where `id` > ? or `id` is not null' ,
bindings : [ 1 ]
} ,
default : {
sql : 'select * from "users" where "id" > ? or "id" is not null' ,
bindings : [ 1 ]
}
} ) ;
2013-12-27 14:44:21 -05:00
} ) ;
it ( "group bys" , function ( ) {
2014-08-26 17:16:46 +02:00
testsql ( qb ( ) . select ( '*' ) . from ( 'users' ) . groupBy ( 'id' , 'email' ) , {
mysql : {
sql : 'select * from `users` group by `id`, `email`' ,
bindings : [ ]
} ,
default : {
sql : 'select * from "users" group by "id", "email"' ,
bindings : [ ]
}
} ) ;
2013-12-27 14:44:21 -05:00
} ) ;
it ( "order bys" , function ( ) {
2014-08-26 17:16:46 +02:00
testsql ( qb ( ) . select ( '*' ) . from ( 'users' ) . orderBy ( 'email' ) . orderBy ( 'age' , 'desc' ) , {
mysql : {
sql : 'select * from `users` order by `email` asc, `age` desc' ,
bindings : [ ]
} ,
default : {
sql : 'select * from "users" order by "email" asc, "age" desc' ,
bindings : [ ]
}
} ) ;
2013-12-27 14:44:21 -05:00
} ) ;
2014-06-27 11:48:09 -04:00
it ( "raw group bys" , function ( ) {
2014-08-26 17:16:46 +02:00
testsql ( qb ( ) . select ( '*' ) . from ( 'users' ) . groupByRaw ( 'id, email' ) , {
mysql : {
sql : 'select * from `users` group by id, email' ,
bindings : [ ]
} ,
default : {
sql : 'select * from "users" group by id, email' ,
bindings : [ ]
}
} ) ;
2014-06-27 11:48:09 -04:00
} ) ;
it ( "raw order bys" , function ( ) {
2014-08-26 17:16:46 +02:00
testsql ( qb ( ) . select ( '*' ) . from ( 'users' ) . orderBy ( raw ( 'col NULLS LAST DESC' ) ) , {
mysql : {
sql : 'select * from `users` order by col NULLS LAST DESC' ,
bindings : [ ]
} ,
default : {
sql : 'select * from "users" order by col NULLS LAST DESC' ,
bindings : [ ]
}
} ) ;
testsql ( qb ( ) . select ( '*' ) . from ( 'users' ) . orderByRaw ( 'col NULLS LAST DESC' ) , {
mysql : {
sql : 'select * from `users` order by col NULLS LAST DESC' ,
bindings : [ ]
} ,
default : {
sql : 'select * from "users" order by col NULLS LAST DESC' ,
bindings : [ ]
}
} ) ;
2014-06-27 11:48:09 -04:00
} ) ;
2014-06-10 13:26:20 -04:00
it ( "multiple order bys" , function ( ) {
2014-08-26 17:16:46 +02:00
testsql ( qb ( ) . select ( '*' ) . from ( 'users' ) . orderBy ( 'email' ) . orderBy ( 'age' , 'desc' ) , {
mysql : {
sql : 'select * from `users` order by `email` asc, `age` desc' ,
bindings : [ ]
} ,
default : {
sql : 'select * from "users" order by "email" asc, "age" desc' ,
bindings : [ ]
}
} ) ;
2014-06-10 13:26:20 -04:00
} ) ;
2013-12-27 14:44:21 -05:00
it ( "havings" , function ( ) {
2014-08-26 17:16:46 +02:00
testsql ( qb ( ) . select ( '*' ) . from ( 'users' ) . having ( 'email' , '>' , 1 ) , {
mysql : 'select * from `users` having `email` > ?' ,
default : 'select * from "users" having "email" > ?'
} ) ;
2014-02-22 17:06:33 -05:00
} ) ;
2013-12-27 14:44:21 -05:00
2014-02-22 17:06:33 -05:00
it ( "grouped having" , function ( ) {
2014-08-26 17:16:46 +02:00
testsql ( qb ( ) . select ( '*' ) . from ( 'users' ) . groupBy ( 'email' ) . having ( 'email' , '>' , 1 ) , {
mysql : 'select * from `users` group by `email` having `email` > ?' ,
default : 'select * from "users" group by "email" having "email" > ?'
} ) ;
2014-02-22 17:06:33 -05:00
} ) ;
2013-12-27 14:44:21 -05:00
2014-02-22 17:06:33 -05:00
it ( "having from" , function ( ) {
2014-08-26 17:16:46 +02:00
testsql ( qb ( ) . select ( 'email as foo_email' ) . from ( 'users' ) . having ( 'foo_email' , '>' , 1 ) , {
mysql : 'select `email` as `foo_email` from `users` having `foo_email` > ?' ,
oracle : 'select "email" "foo_email" from "users" having "foo_email" > ?' ,
default : 'select "email" as "foo_email" from "users" having "foo_email" > ?'
} ) ;
2013-12-27 14:44:21 -05:00
} ) ;
it ( "raw havings" , function ( ) {
2014-08-26 17:16:46 +02:00
testsql ( qb ( ) . select ( '*' ) . from ( 'users' ) . having ( raw ( 'user_foo < user_bar' ) ) , {
mysql : 'select * from `users` having user_foo < user_bar' ,
default : 'select * from "users" having user_foo < user_bar'
} ) ;
2014-02-22 17:06:33 -05:00
} ) ;
2013-12-27 14:44:21 -05:00
2014-02-22 17:06:33 -05:00
it ( "raw or havings" , function ( ) {
2014-08-26 17:16:46 +02:00
testsql ( qb ( ) . select ( '*' ) . from ( 'users' ) . having ( 'baz' , '=' , 1 ) . orHaving ( raw ( 'user_foo < user_bar' ) ) , {
mysql : 'select * from `users` having `baz` = ? or user_foo < user_bar' ,
default : 'select * from "users" having "baz" = ? or user_foo < user_bar'
} ) ;
2013-12-27 14:44:21 -05:00
} ) ;
2014-08-26 17:16:46 +02:00
it ( "limits" , function ( ) {
testsql ( qb ( ) . select ( '*' ) . from ( 'users' ) . limit ( 10 ) , {
mysql : {
sql : 'select * from `users` limit ?' ,
bindings : [ 10 ]
} ,
oracle : {
sql : 'select * from (select * from "users") where rownum <= ?' ,
bindings : [ 10 ]
} ,
default : {
sql : 'select * from "users" limit ?' ,
bindings : [ 10 ]
}
} ) ;
2014-08-21 23:39:12 +02:00
} ) ;
2014-08-26 17:16:46 +02:00
it ( "limits and offsets" , function ( ) {
testsql ( qb ( ) . select ( '*' ) . from ( 'users' ) . offset ( 5 ) . limit ( 10 ) , {
mysql : {
sql : 'select * from `users` limit ? offset ?' ,
bindings : [ 10 , 5 ]
} ,
oracle : {
sql : 'select * from (select row_.*, ROWNUM rownum_ from (select * from "users") row_ where rownum <= ?) where rownum_ > ?' ,
bindings : [ 15 , 5 ]
} ,
default : {
sql : 'select * from "users" limit ? offset ?' ,
bindings : [ 10 , 5 ]
}
} ) ;
2014-08-11 12:25:39 +02:00
} ) ;
2014-08-28 13:43:09 +02:00
it ( "first" , function ( ) {
2014-08-26 17:16:46 +02:00
testsql ( qb ( ) . first ( '*' ) . from ( 'users' ) , {
mysql : {
sql : 'select * from `users` limit ?' ,
bindings : [ 1 ]
} ,
oracle : {
sql : 'select * from (select * from "users") where rownum <= ?' ,
bindings : [ 1 ]
} ,
default : {
sql : 'select * from "users" limit ?' ,
bindings : [ 1 ]
}
} ) ;
2014-08-11 12:25:39 +02:00
} ) ;
2014-08-26 17:16:46 +02:00
it ( "offsets only" , function ( ) {
testsql ( qb ( ) . select ( '*' ) . from ( 'users' ) . offset ( 5 ) , {
mysql : {
2014-08-28 13:43:09 +02:00
sql : 'select * from `users` limit 18446744073709551615 offset ?' ,
2014-08-26 17:16:46 +02:00
bindings : [ 5 ]
} ,
sqlite3 : {
2014-08-28 13:43:09 +02:00
sql : 'select * from "users" limit ? offset ?' ,
bindings : [ - 1 , 5 ]
2014-08-26 17:16:46 +02:00
} ,
postgres : {
2014-08-28 13:43:09 +02:00
sql : 'select * from "users" offset ?' ,
2014-08-26 17:16:46 +02:00
bindings : [ 5 ]
} ,
oracle : {
sql : 'select * from (select row_.*, ROWNUM rownum_ from (select * from "users") row_ where rownum <= ?) where rownum_ > ?' ,
bindings : [ 10000000000005 , 5 ]
} ,
default : {
sql : 'select * from "users" limit ? offset ?' ,
bindings : [ 10000000000005 , 5 ]
}
} ) ;
2014-08-11 12:25:39 +02:00
} ) ;
2013-12-27 14:44:21 -05:00
it ( "where shortcut" , function ( ) {
2014-08-26 17:16:46 +02:00
testsql ( qb ( ) . select ( '*' ) . from ( 'users' ) . where ( 'id' , 1 ) . orWhere ( 'name' , 'foo' ) , {
mysql : {
sql : 'select * from `users` where `id` = ? or `name` = ?' ,
bindings : [ 1 , 'foo' ]
} ,
default : {
sql : 'select * from "users" where "id" = ? or "name" = ?' ,
bindings : [ 1 , 'foo' ]
}
} ) ;
2013-12-27 14:44:21 -05:00
} ) ;
it ( "nested wheres" , function ( ) {
2014-08-26 17:16:46 +02:00
testsql ( qb ( ) . select ( '*' ) . from ( 'users' ) . where ( 'email' , '=' , 'foo' ) . orWhere ( function ( qb ) {
2013-12-27 14:44:21 -05:00
qb . where ( 'name' , '=' , 'bar' ) . where ( 'age' , '=' , 25 ) ;
2014-08-26 17:16:46 +02:00
} ) , {
mysql : {
sql : 'select * from `users` where `email` = ? or (`name` = ? and `age` = ?)' ,
bindings : [ 'foo' , 'bar' , 25 ]
} ,
default : {
sql : 'select * from "users" where "email" = ? or ("name" = ? and "age" = ?)' ,
bindings : [ 'foo' , 'bar' , 25 ]
}
} ) ;
2013-12-27 14:44:21 -05:00
} ) ;
it ( "full sub selects" , function ( ) {
2014-08-26 17:16:46 +02:00
testsql ( qb ( ) . select ( '*' ) . from ( 'users' ) . where ( 'email' , '=' , 'foo' ) . orWhere ( 'id' , '=' , function ( qb ) {
2014-02-22 17:06:33 -05:00
qb . select ( raw ( 'max(id)' ) ) . from ( 'users' ) . where ( 'email' , '=' , 'bar' ) ;
2014-08-26 17:16:46 +02:00
} ) , {
mysql : {
sql : 'select * from `users` where `email` = ? or `id` = (select max(id) from `users` where `email` = ?)' ,
bindings : [ 'foo' , 'bar' ]
} ,
default : {
sql : 'select * from "users" where "email" = ? or "id" = (select max(id) from "users" where "email" = ?)' ,
bindings : [ 'foo' , 'bar' ]
}
} ) ;
2013-12-27 14:44:21 -05:00
} ) ;
it ( "where exists" , function ( ) {
2014-08-26 17:16:46 +02:00
testsql ( qb ( ) . select ( '*' ) . from ( 'orders' ) . whereExists ( function ( qb ) {
2014-02-22 17:06:33 -05:00
qb . select ( '*' ) . from ( 'products' ) . where ( 'products.id' , '=' , raw ( '"orders"."id"' ) ) ;
2014-08-26 17:16:46 +02:00
} ) , {
mysql : {
sql : 'select * from `orders` where exists (select * from `products` where `products`.`id` = "orders"."id")' ,
bindings : [ ]
} ,
default : {
sql : 'select * from "orders" where exists (select * from "products" where "products"."id" = "orders"."id")' ,
bindings : [ ]
}
} ) ;
2014-02-22 17:06:33 -05:00
} ) ;
2013-12-27 14:44:21 -05:00
2014-06-14 09:58:38 -04:00
it ( "where exists with builder" , function ( ) {
2014-08-26 17:16:46 +02:00
testsql ( qb ( ) . select ( '*' ) . from ( 'orders' ) . whereExists ( qb ( ) . select ( '*' ) . from ( 'products' ) . whereRaw ( 'products.id = orders.id' ) ) , {
mysql : {
sql : 'select * from `orders` where exists (select * from `products` where products.id = orders.id)' ,
bindings : [ ]
} ,
default : {
sql : 'select * from "orders" where exists (select * from "products" where products.id = orders.id)' ,
bindings : [ ]
}
} ) ;
2014-05-09 14:42:29 -04:00
} ) ;
2014-02-22 17:06:33 -05:00
it ( "where not exists" , function ( ) {
2014-08-26 17:16:46 +02:00
testsql ( qb ( ) . select ( '*' ) . from ( 'orders' ) . whereNotExists ( function ( qb ) {
2014-02-22 17:06:33 -05:00
qb . select ( '*' ) . from ( 'products' ) . where ( 'products.id' , '=' , raw ( '"orders"."id"' ) ) ;
2014-08-26 17:16:46 +02:00
} ) , {
mysql : {
sql : 'select * from `orders` where not exists (select * from `products` where `products`.`id` = "orders"."id")' ,
bindings : [ ]
} ,
default : {
sql : 'select * from "orders" where not exists (select * from "products" where "products"."id" = "orders"."id")' ,
bindings : [ ]
}
} ) ;
2014-02-22 17:06:33 -05:00
} ) ;
2013-12-27 14:44:21 -05:00
2014-02-22 17:06:33 -05:00
it ( "or where exists" , function ( ) {
2014-08-26 17:16:46 +02:00
testsql ( qb ( ) . select ( '*' ) . from ( 'orders' ) . where ( 'id' , '=' , 1 ) . orWhereExists ( function ( qb ) {
2014-02-22 17:06:33 -05:00
qb . select ( '*' ) . from ( 'products' ) . where ( 'products.id' , '=' , raw ( '"orders"."id"' ) ) ;
2014-08-26 17:16:46 +02:00
} ) , {
mysql : {
sql : 'select * from `orders` where `id` = ? or exists (select * from `products` where `products`.`id` = "orders"."id")' ,
bindings : [ 1 ]
} ,
default : {
sql : 'select * from "orders" where "id" = ? or exists (select * from "products" where "products"."id" = "orders"."id")' ,
bindings : [ 1 ]
}
} ) ;
2014-02-22 17:06:33 -05:00
} ) ;
2013-12-27 14:44:21 -05:00
2014-02-22 17:06:33 -05:00
it ( "or where not exists" , function ( ) {
2014-08-26 17:16:46 +02:00
testsql ( qb ( ) . select ( '*' ) . from ( 'orders' ) . where ( 'id' , '=' , 1 ) . orWhereNotExists ( function ( qb ) {
2014-02-22 17:06:33 -05:00
qb . select ( '*' ) . from ( 'products' ) . where ( 'products.id' , '=' , raw ( '"orders"."id"' ) ) ;
2014-08-26 17:16:46 +02:00
} ) , {
mysql : {
sql : 'select * from `orders` where `id` = ? or not exists (select * from `products` where `products`.`id` = "orders"."id")' ,
bindings : [ 1 ]
} ,
default : {
sql : 'select * from "orders" where "id" = ? or not exists (select * from "products" where "products"."id" = "orders"."id")' ,
bindings : [ 1 ]
}
} ) ;
2013-12-27 14:44:21 -05:00
} ) ;
it ( "basic joins" , function ( ) {
2014-08-26 17:16:46 +02:00
testsql ( qb ( ) . select ( '*' ) . from ( 'users' ) . join ( 'contacts' , 'users.id' , '=' , 'contacts.id' ) . leftJoin ( 'photos' , 'users.id' , '=' , 'photos.id' ) , {
mysql : {
sql : 'select * from `users` inner join `contacts` on `users`.`id` = `contacts`.`id` left join `photos` on `users`.`id` = `photos`.`id`' ,
bindings : [ ]
} ,
default : {
sql : 'select * from "users" inner join "contacts" on "users"."id" = "contacts"."id" left join "photos" on "users"."id" = "photos"."id"' ,
bindings : [ ]
}
} ) ;
2013-12-27 14:44:21 -05:00
} ) ;
it ( "complex join" , function ( ) {
2014-08-26 17:16:46 +02:00
testsql ( qb ( ) . select ( '*' ) . from ( 'users' ) . join ( 'contacts' , function ( qb ) {
2013-12-27 14:44:21 -05:00
qb . on ( 'users.id' , '=' , 'contacts.id' ) . orOn ( 'users.name' , '=' , 'contacts.name' ) ;
2014-08-26 17:16:46 +02:00
} ) , {
mysql : {
sql : 'select * from `users` inner join `contacts` on `users`.`id` = `contacts`.`id` or `users`.`name` = `contacts`.`name`' ,
bindings : [ ]
} ,
default : {
sql : 'select * from "users" inner join "contacts" on "users"."id" = "contacts"."id" or "users"."name" = "contacts"."name"' ,
bindings : [ ]
}
} ) ;
2013-12-27 14:44:21 -05:00
} ) ;
it ( "raw expressions in select" , function ( ) {
2014-08-26 17:16:46 +02:00
testsql ( qb ( ) . select ( raw ( 'substr(foo, 6)' ) ) . from ( 'users' ) , {
mysql : {
sql : 'select substr(foo, 6) from `users`' ,
bindings : [ ]
} ,
default : {
sql : 'select substr(foo, 6) from "users"' ,
bindings : [ ]
}
} ) ;
2013-12-27 14:44:21 -05:00
} ) ;
// it("list methods gets array of column values", function() {
2014-08-26 17:16:46 +02:00
// chain = qb().getConnection().shouldReceive('select').once().andReturn(array({foo: 'bar'}, {'foo': 'baz'}));
2013-12-27 14:44:21 -05:00
// $builder.getProcessor().shouldReceive('processSelect').once().with($builder, array({foo: 'bar'}, {foo: 'baz'})).andReturnUsing(function($query, $results)
// {
// return $results;
// });
// $results = $builder.from('users').where('id', '=', 1).lists('foo');
// equal(array('bar', 'baz'), $results);
2014-08-26 17:16:46 +02:00
// // chain = qb().getConnection().shouldReceive('select').once().andReturn(array(array('id' => 1, 'foo' => 'bar'), array('id' => 10, 'foo' => 'baz')));
2013-12-27 14:44:21 -05:00
// // $builder.getProcessor().shouldReceive('processSelect').once().with($builder, array(array('id' => 1, 'foo' => 'bar'), array('id' => 10, 'foo' => 'baz'))).andReturnUsing(function($query, $results)
// {
// return $results;
// });
// $results = $builder.from('users').where('id', '=', 1).lists('foo', 'id');
// // equal(array(1 => 'bar', 10 => 'baz'), $results);
// });
// it("pluck method returns single column", function() {
2014-08-26 17:16:46 +02:00
// chain = qb().getConnection().shouldReceive('select').once().with('select "foo" from "users" where "id" = ? limit 1', [1]).andReturn(array({foo: 'bar'}));
2013-12-27 14:44:21 -05:00
// $builder.getProcessor().shouldReceive('processSelect').once().with($builder, array({foo: 'bar'})).andReturn(array({foo: 'bar'}));
// $results = $builder.from('users').where('id', '=', 1).pluck('foo');
// equal('bar', $results);
// });
it ( "aggregate functions" , function ( ) {
2014-08-26 17:16:46 +02:00
testsql ( qb ( ) . from ( 'users' ) . count ( ) , {
mysql : {
sql : 'select count(*) from `users`' ,
bindings : [ ]
} ,
default : {
sql : 'select count(*) from "users"' ,
bindings : [ ]
}
} ) ;
2014-02-22 17:06:33 -05:00
} ) ;
2013-12-27 14:44:21 -05:00
2014-02-22 17:06:33 -05:00
it ( "aggregate alias" , function ( ) {
2014-08-26 17:16:46 +02:00
testsql ( qb ( ) . from ( 'users' ) . count ( '* as all' ) , {
mysql : {
sql : 'select count(*) as `all` from `users`' ,
bindings : [ ]
} ,
oracle : {
sql : 'select count(*) "all" from "users"' ,
bindings : [ ]
} ,
default : {
sql : 'select count(*) as "all" from "users"' ,
bindings : [ ]
}
} ) ;
2014-08-11 12:25:39 +02:00
} ) ;
2014-02-22 17:06:33 -05:00
it ( "max" , function ( ) {
2014-08-26 17:16:46 +02:00
testsql ( qb ( ) . from ( 'users' ) . max ( 'id' ) , {
mysql : {
sql : 'select max(`id`) from `users`' ,
bindings : [ ]
} ,
default : {
sql : 'select max("id") from "users"' ,
bindings : [ ]
}
} ) ;
2014-02-22 17:06:33 -05:00
} ) ;
2013-12-27 14:44:21 -05:00
2014-02-22 17:06:33 -05:00
it ( "min" , function ( ) {
2014-08-26 17:16:46 +02:00
testsql ( qb ( ) . from ( 'users' ) . max ( 'id' ) , {
mysql : {
sql : 'select max(`id`) from `users`' ,
bindings : [ ]
} ,
default : {
sql : 'select max("id") from "users"' ,
bindings : [ ]
}
} ) ;
2014-02-22 17:06:33 -05:00
} ) ;
2013-12-27 14:44:21 -05:00
2014-02-22 17:06:33 -05:00
it ( "sum" , function ( ) {
2014-08-26 17:16:46 +02:00
testsql ( qb ( ) . from ( 'users' ) . sum ( 'id' ) , {
mysql : {
sql : 'select sum(`id`) from `users`' ,
bindings : [ ]
} ,
default : {
sql : 'select sum("id") from "users"' ,
bindings : [ ]
}
} ) ;
2013-12-27 14:44:21 -05:00
} ) ;
it ( "insert method" , function ( ) {
2014-08-26 17:16:46 +02:00
testsql ( qb ( ) . into ( 'users' ) . insert ( { 'email' : 'foo' } ) , {
mysql : {
sql : 'insert into `users` (`email`) values (?)' ,
bindings : [ 'foo' ]
} ,
default : {
sql : 'insert into "users" ("email") values (?)' ,
bindings : [ 'foo' ]
}
} ) ;
2013-12-27 14:44:21 -05:00
} ) ;
2014-08-26 17:16:46 +02:00
it ( "multiple inserts" , function ( ) {
testsql ( qb ( ) . from ( 'users' ) . insert ( [ { email : 'foo' , name : 'taylor' } , { email : 'bar' , name : 'dayle' } ] ) , {
mysql : {
sql : 'insert into `users` (`email`, `name`) values (?, ?), (?, ?)' ,
bindings : [ 'foo' , 'taylor' , 'bar' , 'dayle' ]
} ,
sqlite3 : {
sql : 'insert into "users" ("email", "name") select ? as "email", ? as "name" union all select ? as "email", ? as "name"' ,
bindings : [ 'foo' , 'taylor' , 'bar' , 'dayle' ]
} ,
oracle : {
sql : 'begin execute immediate \'insert into "users" ("email", "name") values (:1, :2)\' using ?, ?; execute immediate \'insert into "users" ("email", "name") values (:1, :2)\' using ?, ?;end;' ,
bindings : [ 'foo' , 'taylor' , 'bar' , 'dayle' ]
} ,
default : {
sql : 'insert into "users" ("email", "name") values (?, ?), (?, ?)' ,
bindings : [ 'foo' , 'taylor' , 'bar' , 'dayle' ]
}
} ) ;
2014-08-13 21:37:22 +02:00
} ) ;
2014-08-26 17:16:46 +02:00
it ( "multiple inserts with returning" , function ( ) {
// returning only supported directly by postgres and with workaround with oracle
// other databases implicitly return the inserted id
testsql ( qb ( ) . from ( 'users' ) . insert ( [ { email : 'foo' , name : 'taylor' } , { email : 'bar' , name : 'dayle' } ] , 'id' ) , {
mysql : {
sql : 'insert into `users` (`email`, `name`) values (?, ?), (?, ?)' ,
bindings : [ 'foo' , 'taylor' , 'bar' , 'dayle' ]
} ,
sqlite3 : {
sql : "insert into \"users\" (\"email\", \"name\") select ? as \"email\", ? as \"name\" union all select ? as \"email\", ? as \"name\"" ,
} ,
postgres : {
sql : "insert into \"users\" (\"email\", \"name\") values (?, ?), (?, ?) returning \"id\"" ,
bindings : [ 'foo' , 'taylor' , 'bar' , 'dayle' ]
} ,
oracle : {
sql : "begin execute immediate 'insert into \"users\" (\"email\", \"name\") values (:1, :2) returning ROWID into :3' using ?, ?, out ?; execute immediate 'insert into \"users\" (\"email\", \"name\") values (:1, :2) returning ROWID into :3' using ?, ?, out ?;end;" ,
bindings : function ( bindings ) {
expect ( bindings . length ) . to . equal ( 6 ) ;
expect ( bindings [ 0 ] ) . to . equal ( 'foo' ) ;
expect ( bindings [ 1 ] ) . to . equal ( 'taylor' ) ;
expect ( bindings [ 2 ] . toString ( ) ) . to . equal ( '[object ReturningHelper:id]' ) ;
expect ( bindings [ 3 ] ) . to . equal ( 'bar' ) ;
expect ( bindings [ 4 ] ) . to . equal ( 'dayle' ) ;
expect ( bindings [ 5 ] . toString ( ) ) . to . equal ( '[object ReturningHelper:id]' ) ;
}
} ,
default : {
sql : 'als' ,
bindings : [ 'foo' , 'taylor' , 'bar' , 'dayle' ]
}
} ) ;
2014-08-13 21:37:22 +02:00
} ) ;
2014-08-26 17:16:46 +02:00
it ( "multiple inserts with multiple returning" , function ( ) {
testsql ( qb ( ) . from ( 'users' ) . insert ( [ { email : 'foo' , name : 'taylor' } , { email : 'bar' , name : 'dayle' } ] , [ 'id' , 'name' ] ) , {
mysql : {
sql : 'insert into `users` (`email`, `name`) values (?, ?), (?, ?)' ,
bindings : [ 'foo' , 'taylor' , 'bar' , 'dayle' ]
} ,
sqlite3 : {
sql : "insert into \"users\" (\"email\", \"name\") select ? as \"email\", ? as \"name\" union all select ? as \"email\", ? as \"name\"" ,
bindings : [ 'foo' , 'taylor' , 'bar' , 'dayle' ]
} ,
postgres : {
sql : 'insert into "users" ("email", "name") values (?, ?), (?, ?) returning "id", "name"' ,
bindings : [ 'foo' , 'taylor' , 'bar' , 'dayle' ]
} ,
oracle : {
sql : "begin execute immediate 'insert into \"users\" (\"email\", \"name\") values (:1, :2) returning ROWID into :3' using ?, ?, out ?; execute immediate 'insert into \"users\" (\"email\", \"name\") values (:1, :2) returning ROWID into :3' using ?, ?, out ?;end;" ,
bindings : function ( bindings ) {
expect ( bindings . length ) . to . equal ( 6 ) ;
expect ( bindings [ 0 ] ) . to . equal ( 'foo' ) ;
expect ( bindings [ 1 ] ) . to . equal ( 'taylor' ) ;
expect ( bindings [ 2 ] . toString ( ) ) . to . equal ( '[object ReturningHelper:id:name]' ) ;
expect ( bindings [ 3 ] ) . to . equal ( 'bar' ) ;
expect ( bindings [ 4 ] ) . to . equal ( 'dayle' ) ;
expect ( bindings [ 5 ] . toString ( ) ) . to . equal ( '[object ReturningHelper:id:name]' ) ;
}
} ,
default : {
sql : '' ,
}
} ) ;
2014-08-13 21:37:22 +02:00
} ) ;
2013-12-27 14:44:21 -05:00
it ( "insert method respects raw bindings" , function ( ) {
2014-08-26 17:16:46 +02:00
testsql ( qb ( ) . insert ( { 'email' : raw ( 'CURRENT TIMESTAMP' ) } ) . into ( 'users' ) , {
mysql : {
sql : 'insert into `users` (`email`) values (CURRENT TIMESTAMP)' ,
bindings : [ ]
} ,
default : {
sql : 'insert into "users" ("email") values (CURRENT TIMESTAMP)' ,
bindings : [ ]
}
} ) ;
2013-12-27 14:44:21 -05:00
} ) ;
2014-06-03 00:47:54 -04:00
it ( "normalizes for missing keys in insert" , function ( ) {
var data = [ { a : 1 } , { b : 2 } , { a : 2 , c : 3 } ] ;
2014-08-26 17:16:46 +02:00
testsql ( qb ( ) . insert ( data ) . into ( 'table' ) , {
mysql : {
sql : 'insert into `table` (`a`, `b`, `c`) values (?, ?, ?), (?, ?, ?), (?, ?, ?)' ,
bindings : [ 1 , undefined , undefined , undefined , 2 , undefined , 2 , undefined , 3 ]
} ,
sqlite3 : {
sql : 'insert into "table" ("a", "b", "c") select ? as "a", ? as "b", ? as "c" union all select ? as "a", ? as "b", ? as "c" union all select ? as "a", ? as "b", ? as "c"' ,
bindings : [ 1 , undefined , undefined , undefined , 2 , undefined , 2 , undefined , 3 ]
} ,
oracle : {
sql : "begin execute immediate 'insert into \"table\" (\"a\", \"b\", \"c\") values (:1, :2, :3)' using ?, ?, ?; execute immediate 'insert into \"table\" (\"a\", \"b\", \"c\") values (:1, :2, :3)' using ?, ?, ?; execute immediate 'insert into \"table\" (\"a\", \"b\", \"c\") values (:1, :2, :3)' using ?, ?, ?;end;" ,
bindings : [ 1 , undefined , undefined , undefined , 2 , undefined , 2 , undefined , 3 ]
} ,
default : {
sql : 'insert into "table" ("a", "b", "c") values (?, ?, ?), (?, ?, ?), (?, ?, ?)' ,
bindings : [ 1 , undefined , undefined , undefined , 2 , undefined , 2 , undefined , 3 ]
}
} ) ;
2014-06-03 00:47:54 -04:00
} ) ;
2013-12-27 14:44:21 -05:00
it ( "update method" , function ( ) {
2014-08-26 17:16:46 +02:00
testsql ( qb ( ) . update ( { 'email' : 'foo' , 'name' : 'bar' } ) . table ( 'users' ) . where ( 'id' , '=' , 1 ) , {
mysql : {
sql : 'update `users` set `email` = ?, `name` = ? where `id` = ?' ,
bindings : [ 'foo' , 'bar' , 1 ]
} ,
default : {
sql : 'update "users" set "email" = ?, "name" = ? where "id" = ?' ,
bindings : [ 'foo' , 'bar' , 1 ]
}
} ) ;
2014-02-22 17:06:33 -05:00
} ) ;
2013-12-27 14:44:21 -05:00
2014-02-23 15:38:53 -05:00
it ( "should allow for 'null' updates" , function ( ) {
2014-08-26 17:16:46 +02:00
testsql ( qb ( ) . update ( { email : null , 'name' : 'bar' } ) . table ( 'users' ) . where ( 'id' , 1 ) , {
mysql : {
sql : 'update `users` set `email` = ?, `name` = ? where `id` = ?' ,
bindings : [ null , 'bar' , 1 ]
} ,
default : {
sql : 'update "users" set "email" = ?, "name" = ? where "id" = ?' ,
bindings : [ null , 'bar' , 1 ]
}
} ) ;
2014-02-23 15:38:53 -05:00
} ) ;
2014-02-22 17:06:33 -05:00
it ( "order by, limit" , function ( ) {
2014-08-26 17:16:46 +02:00
// update with limit works only with mysql and derrivates
testsql ( qb ( ) . from ( 'users' ) . where ( 'id' , '=' , 1 ) . orderBy ( 'foo' , 'desc' ) . limit ( 5 ) . update ( { email : 'foo' , name : 'bar' } ) , {
mysql : {
sql : 'update `users` set `email` = ?, `name` = ? where `id` = ? order by `foo` desc limit ?' ,
bindings : [ 'foo' , 'bar' , 1 , 5 ]
} ,
default : {
sql : 'update "users" set "email" = ?, "name" = ? where "id" = ?' ,
bindings : [ 'foo' , 'bar' , 1 ]
}
} ) ;
2013-12-27 14:44:21 -05:00
} ) ;
it ( "update method with joins mysql" , function ( ) {
2014-08-26 17:16:46 +02:00
testsql ( qb ( ) . from ( 'users' ) . join ( 'orders' , 'users.id' , 'orders.user_id' ) . where ( 'users.id' , '=' , 1 ) . update ( { 'email' : 'foo' , 'name' : 'bar' } ) , {
mysql : {
sql : 'update `users` inner join `orders` on `users`.`id` = `orders`.`user_id` set `email` = ?, `name` = ? where `users`.`id` = ?' ,
bindings : [ 'foo' , 'bar' , 1 ]
} ,
sqlite3 : { // TODO: This is wrong
sql : 'update "users" inner join "orders" on "users"."id" = "orders"."user_id" set "email" = ?, "name" = ? where "users"."id" = ?' ,
bindings : [ 'foo' , 'bar' , 1 ]
} ,
default : {
sql : "update \"users\" set \"email\" = ?, \"name\" = ? where \"users\".\"id\" = ?" ,
bindings : [ 'foo' , 'bar' , 1 ]
} ,
} ) ;
2013-12-27 14:44:21 -05:00
} ) ;
2014-07-08 07:06:39 -04:00
it ( "update method with limit mysql" , function ( ) {
2014-08-26 17:16:46 +02:00
// limit works only with mysql or derrivates
testsql ( qb ( ) . from ( 'users' ) . where ( 'users.id' , '=' , 1 ) . update ( { 'email' : 'foo' , 'name' : 'bar' } ) . limit ( 1 ) , {
mysql : {
sql : 'update `users` set `email` = ?, `name` = ? where `users`.`id` = ? limit ?' ,
bindings : [ 'foo' , 'bar' , 1 , 1 ]
} ,
default : {
sql : 'update "users" set "email" = ?, "name" = ? where "users"."id" = ?' ,
bindings : [ 'foo' , 'bar' , 1 ]
}
} ) ;
2014-07-08 07:06:39 -04:00
} ) ;
2013-12-27 14:44:21 -05:00
it ( "update method without joins on postgres" , function ( ) {
2014-08-26 17:16:46 +02:00
testsql ( qb ( ) . from ( 'users' ) . where ( 'id' , '=' , 1 ) . update ( { email : 'foo' , name : 'bar' } ) , {
mysql : {
sql : 'update `users` set `email` = ?, `name` = ? where `id` = ?' ,
bindings : [ 'foo' , 'bar' , 1 ]
} ,
default : {
sql : 'update "users" set "email" = ?, "name" = ? where "id" = ?' ,
bindings : [ 'foo' , 'bar' , 1 ]
}
} ) ;
2013-12-27 14:44:21 -05:00
} ) ;
// TODO:
// it("update method with joins on postgres", function() {
2014-08-26 17:16:46 +02:00
// chain = qb().from('users').join('orders', 'users.id', '=', 'orders.user_id').where('users.id', '=', 1).update({email: 'foo', name: 'bar'}).toSQL();
2013-12-27 14:44:21 -05:00
// expect(chain.sql).to.equal('update "users" set "email" = ?, "name" = ? from "orders" where "users"."id" = ? and "users"."id" = "orders"."user_id"');
// expect(chain.sql).to.eql(['foo', 'bar', 1]);
// });
it ( "update method respects raw" , function ( ) {
2014-08-26 17:16:46 +02:00
testsql ( qb ( ) . from ( 'users' ) . where ( 'id' , '=' , 1 ) . update ( { email : raw ( 'foo' ) , name : 'bar' } ) , {
mysql : {
sql : 'update `users` set `email` = foo, `name` = ? where `id` = ?' ,
bindings : [ 'bar' , 1 ]
} ,
default : {
sql : 'update "users" set "email" = foo, "name" = ? where "id" = ?' ,
bindings : [ 'bar' , 1 ]
}
} ) ;
2013-12-27 14:44:21 -05:00
} ) ;
it ( "delete method" , function ( ) {
2014-08-26 17:16:46 +02:00
testsql ( qb ( ) . from ( 'users' ) . where ( 'email' , '=' , 'foo' ) . delete ( ) , {
mysql : {
sql : 'delete from `users` where `email` = ?' ,
bindings : [ 'foo' ]
} ,
default : {
sql : 'delete from "users" where "email" = ?' ,
bindings : [ 'foo' ]
}
} ) ;
2013-12-27 14:44:21 -05:00
} ) ;
it ( "truncate method" , function ( ) {
2014-08-26 17:16:46 +02:00
testsql ( qb ( ) . table ( 'users' ) . truncate ( ) , {
mysql : {
sql : 'truncate `users`' ,
bindings : [ ]
} ,
sqlite3 : {
sql : 'delete from sqlite_sequence where name = "users"' ,
bindings : [ ] ,
output : function ( output ) {
expect ( typeof output ) . to . equal ( 'function' ) ;
}
} ,
postgres : {
sql : 'truncate "users" restart identity' ,
bindings : [ ]
} ,
oracle : {
sql : 'truncate table "users"' ,
bindings : [ ]
} ,
default : {
sql : '' ,
bindings : [ ]
}
} ) ;
2013-12-27 14:44:21 -05:00
} ) ;
2014-08-26 17:16:46 +02:00
it ( "insert get id" , function ( ) {
testsql ( qb ( ) . from ( 'users' ) . insert ( { email : 'foo' } , 'id' ) , {
mysql : {
sql : 'insert into `users` (`email`) values (?)' ,
bindings : [ 'foo' ]
} ,
postgres : {
sql : 'insert into "users" ("email") values (?) returning "id"' ,
bindings : [ 'foo' ]
} ,
oracle : {
sql : 'insert into "users" ("email") values (?) returning ROWID into ?' ,
bindings : function ( bindings ) {
expect ( bindings . length ) . to . equal ( 2 ) ;
expect ( bindings [ 0 ] ) . to . equal ( 'foo' ) ;
expect ( bindings [ 1 ] . toString ( ) ) . to . equal ( '[object ReturningHelper:id]' ) ;
}
} ,
default : {
sql : 'insert into "users" ("email") values (?)' ,
bindings : [ 'foo' ]
}
} ) ;
2013-12-27 14:44:21 -05:00
} ) ;
2014-08-26 17:16:46 +02:00
it ( "wrapping" , function ( ) {
testsql ( qb ( ) . select ( '*' ) . from ( 'users' ) , {
mysql : 'select * from `users`' ,
default : 'select * from "users"'
} ) ;
2013-12-27 14:44:21 -05:00
} ) ;
2014-08-26 17:16:46 +02:00
it ( "order by desc" , function ( ) {
testsql ( qb ( ) . select ( '*' ) . from ( 'users' ) . orderBy ( 'email' , 'desc' ) , {
mysql : 'select * from `users` order by `email` desc' ,
default : 'select * from "users" order by "email" desc'
} ) ;
2013-12-27 14:44:21 -05:00
} ) ;
// it("sql server limits and offsets", function() {
// $builder = $this.getSqlServerBuilder();
2014-04-15 11:43:47 -04:00
// $builder.select('*').from('users').limit(10).toSQL();
2013-12-27 14:44:21 -05:00
// expect(chain.sql).to.equal('select top 10 * from [users]');
// $builder = $this.getSqlServerBuilder();
2014-04-15 11:43:47 -04:00
// $builder.select('*').from('users').offset(10).toSQL();
2013-12-27 14:44:21 -05:00
// expect(chain.sql).to.equal('select * from (select *, row_number() over (order by (select 0)) as row_num from [users]) as temp_table where row_num >= 11');
// $builder = $this.getSqlServerBuilder();
2014-04-15 11:43:47 -04:00
// $builder.select('*').from('users').offset(10).limit(10).toSQL();
2013-12-27 14:44:21 -05:00
// expect(chain.sql).to.equal('select * from (select *, row_number() over (order by (select 0)) as row_num from [users]) as temp_table where row_num between 11 and 20');
// $builder = $this.getSqlServerBuilder();
2014-04-15 11:43:47 -04:00
// $builder.select('*').from('users').offset(10).limit(10).orderBy('email', 'desc').toSQL();
2013-12-27 14:44:21 -05:00
// expect(chain.sql).to.equal('select * from (select *, row_number() over (order by [email] desc) as row_num from [users]) as temp_table where row_num between 11 and 20');
// });
it ( "providing null or false as second parameter builds correctly" , function ( ) {
2014-08-26 17:16:46 +02:00
testsql ( qb ( ) . select ( '*' ) . from ( 'users' ) . where ( 'foo' , null ) , {
mysql : 'select * from `users` where `foo` is null' ,
default : 'select * from "users" where "foo" is null'
} ) ;
2013-12-27 14:44:21 -05:00
} ) ;
2014-08-26 17:16:46 +02:00
it ( "lock for update" , function ( ) {
testsql ( qb ( ) . transacting ( { } ) . select ( '*' ) . from ( 'foo' ) . where ( 'bar' , '=' , 'baz' ) . forUpdate ( ) , {
mysql : {
sql : 'select * from `foo` where `bar` = ? for update' ,
bindings : [ 'baz' ]
} ,
postgres : {
sql : 'select * from "foo" where "bar" = ? for update' ,
bindings : [ 'baz' ]
} ,
oracle : {
sql : 'select * from "foo" where "bar" = ? for update' ,
bindings : [ 'baz' ]
} ,
default : {
sql : 'select * from "foo" where "bar" = ?' ,
bindings : [ 'baz' ]
}
} ) ;
2014-02-22 17:06:33 -05:00
} ) ;
2013-12-27 14:44:21 -05:00
2014-08-26 17:16:46 +02:00
it ( "lock in share mode" , function ( ) {
testsql ( qb ( ) . transacting ( { } ) . select ( '*' ) . from ( 'foo' ) . where ( 'bar' , '=' , 'baz' ) . forShare ( ) , {
mysql : {
sql : 'select * from `foo` where `bar` = ? lock in share mode' ,
bindings : [ 'baz' ]
} ,
postgres : {
sql : "select * from \"foo\" where \"bar\" = ? for share" ,
bindings : [ 'baz' ]
} ,
default : {
sql : 'select * from "foo" where "bar" = ?' ,
bindings : [ 'baz' ]
}
} ) ;
2013-12-27 14:44:21 -05:00
} ) ;
it ( "should warn when trying to use forUpdate outside of a transaction" , function ( ) {
2014-08-26 17:16:46 +02:00
testsql ( qb ( ) . select ( '*' ) . from ( 'foo' ) . where ( 'bar' , '=' , 'baz' ) . forUpdate ( ) , {
mysql : {
sql : 'select * from `foo` where `bar` = ?' ,
bindings : [ 'baz' ]
} ,
default : {
sql : 'select * from "foo" where "bar" = ?' ,
bindings : [ 'baz' ]
}
} ) ;
2013-12-27 14:44:21 -05:00
} ) ;
// it("SQLServer lock", function() {
// $builder = $this.getSqlServerBuilder();
2014-04-15 11:43:47 -04:00
// $builder.select('*').from('foo').where('bar', '=', 'baz').lock().toSQL();
2013-12-27 14:44:21 -05:00
// expect(chain.sql).to.equal('select * from [foo] with(rowlock,updlock,holdlock) where [bar] = ?');
// expect(chain.bindings).to.eql(array('baz'));
// $builder = $this.getSqlServerBuilder();
2014-04-15 11:43:47 -04:00
// $builder.select('*').from('foo').where('bar', '=', 'baz').lock(false).toSQL();
2013-12-27 14:44:21 -05:00
// expect(chain.sql).to.equal('select * from [foo] with(rowlock,holdlock) where [bar] = ?');
// expect(chain.bindings).to.eql(array('baz'));
// });
it ( 'allows insert values of sub-select, #121' , function ( ) {
2014-08-26 17:16:46 +02:00
testsql ( qb ( ) . table ( 'entries' ) . insert ( {
2013-12-27 14:44:21 -05:00
secret : 123 ,
2014-08-26 17:16:46 +02:00
sequence : raw ( qb ( ) . count ( '*' ) . from ( 'entries' ) . where ( 'secret' , 123 ) ) . wrap ( '(' , ')' )
} ) , {
mysql : {
sql : 'insert into `entries` (`secret`, `sequence`) values (?, (select count(*) from `entries` where `secret` = ?))' ,
bindings : [ 123 , 123 ]
} ,
default : {
sql : 'insert into "entries" ("secret", "sequence") values (?, (select count(*) from "entries" where "secret" = ?))' ,
bindings : [ 123 , 123 ]
}
} ) ;
2013-12-27 14:44:21 -05:00
} ) ;
it ( 'allows left outer join with raw values' , function ( ) {
2014-08-26 17:16:46 +02:00
testsql ( qb ( ) . select ( '*' ) . from ( 'student' ) . leftOuterJoin ( 'student_languages' , function ( ) {
2014-02-22 17:06:33 -05:00
this . on ( 'student.id' , 'student_languages.student_id' ) . andOn ( 'student_languages.code' , raw ( '?' , 'en_US' ) ) ;
2014-08-26 17:16:46 +02:00
} ) , {
mysql : {
sql : 'select * from `student` left outer join `student_languages` on `student`.`id` = `student_languages`.`student_id` and `student_languages`.`code` = ?' ,
bindings : [ 'en_US' ]
} ,
default : {
sql : 'select * from "student" left outer join "student_languages" on "student"."id" = "student_languages"."student_id" and "student_languages"."code" = ?' ,
bindings : [ 'en_US' ]
}
} ) ;
2013-12-27 14:44:21 -05:00
} ) ;
2014-02-21 20:37:24 -05:00
it ( 'should not break with null call #182' , function ( ) {
2014-08-26 17:16:46 +02:00
testsql ( qb ( ) . from ( 'test' ) . limit ( null ) . offset ( null ) , {
mysql : {
sql : 'select * from `test`' ,
bindings : [ ]
} ,
default : {
sql : 'select * from "test"' ,
bindings : [ ]
}
} ) ;
2014-02-21 20:37:24 -05:00
} ) ;
2014-02-21 20:47:46 -05:00
it ( 'allows passing builder into where clause, #162' , function ( ) {
2014-08-26 17:16:46 +02:00
var chain = qb ( ) . from ( 'chapter' ) . select ( 'id' ) . where ( 'book' , 1 ) ;
var page = qb ( ) . from ( 'page' ) . select ( 'id' ) . whereIn ( 'chapter_id' , chain ) ;
var word = qb ( ) . from ( 'word' ) . select ( 'id' ) . whereIn ( 'page_id' , page ) ;
var three = chain . clone ( ) . del ( ) ;
var two = page . clone ( ) . del ( ) ;
var one = word . clone ( ) . del ( ) ;
testsql ( one , {
mysql : {
sql : 'delete from `word` where `page_id` in (select `id` from `page` where `chapter_id` in (select `id` from `chapter` where `book` = ?))' ,
bindings : [ 1 ]
} ,
default : {
sql : 'delete from "word" where "page_id" in (select "id" from "page" where "chapter_id" in (select "id" from "chapter" where "book" = ?))' ,
bindings : [ 1 ]
}
} ) ;
2014-04-21 09:50:30 -04:00
2014-08-26 17:16:46 +02:00
testsql ( two , {
mysql : {
sql : 'delete from `page` where `chapter_id` in (select `id` from `chapter` where `book` = ?)' ,
bindings : [ 1 ]
} ,
default : {
sql : 'delete from "page" where "chapter_id" in (select "id" from "chapter" where "book" = ?)' ,
bindings : [ 1 ]
}
} ) ;
2014-04-21 09:50:30 -04:00
2014-08-26 17:16:46 +02:00
testsql ( three , {
mysql : {
sql : 'delete from `chapter` where `book` = ?' ,
bindings : [ 1 ]
} ,
default : {
sql : 'delete from "chapter" where "book" = ?' ,
bindings : [ 1 ]
}
} ) ;
2014-02-21 20:47:46 -05:00
} ) ;
2014-04-15 11:43:47 -04:00
it ( 'allows specifying the columns and the query for insert, #211' , function ( ) {
2014-08-26 17:16:46 +02:00
if ( clientName === 'sqlite3' ) {
// TODO: THIS IS NOT WORKING
console . log ( "This tests fails with SQLite3" ) ;
return ;
}
2014-04-15 11:43:47 -04:00
var id = 1 ;
var email = 'foo@bar.com' ;
2014-08-26 17:16:46 +02:00
testsql ( qb ( ) . into ( raw ( 'recipients (recipient_id, email)' ) ) . insert (
qb ( ) . select ( raw ( '?, ?' , [ id , email ] ) ) . whereNotExists ( function ( ) {
2014-04-15 13:10:32 -04:00
this . select ( 1 ) . from ( 'recipients' ) . where ( 'recipient_id' , id ) ;
2014-08-26 17:16:46 +02:00
} ) ) , {
mysql : {
sql : 'insert into recipients (recipient_id, email) select ?, ? where not exists (select 1 from `recipients` where `recipient_id` = ?)' ,
bindings : [ 1 , 'foo@bar.com' , 1 ]
} ,
default : {
sql : 'insert into recipients (recipient_id, email) select ?, ? where not exists (select 1 from "recipients" where "recipient_id" = ?)' ,
bindings : [ 1 , 'foo@bar.com' , 1 ]
}
} ) ;
2014-04-15 11:43:47 -04:00
} ) ;
2014-04-21 22:15:06 -04:00
it ( 'does an update with join, #191' , function ( ) {
var setObj = { 'tblPerson.City' : 'Boonesville' } ;
2014-08-26 17:16:46 +02:00
var query = qb ( ) . table ( 'tblPerson' ) . update ( setObj )
2014-04-21 22:15:06 -04:00
. join ( 'tblPersonData' , 'tblPersonData.PersonId' , '=' , 'tblPerson.PersonId' )
. where ( 'tblPersonData.DataId' , 1 )
. where ( 'tblPerson.PersonId' , 5 ) ;
2014-08-26 17:16:46 +02:00
testsql ( query , {
mysql : {
sql : 'update `tblPerson` inner join `tblPersonData` on `tblPersonData`.`PersonId` = `tblPerson`.`PersonId` set `tblPerson`.`City` = ? where `tblPersonData`.`DataId` = ? and `tblPerson`.`PersonId` = ?' ,
bindings : [ 'Boonesville' , 1 , 5 ]
} ,
sqlite3 : {
// TODO: THIS IS NOT WORKING
sql : 'update "tblPerson" inner join "tblPersonData" on "tblPersonData"."PersonId" = "tblPerson"."PersonId" set "tblPerson"."City" = ? where "tblPersonData"."DataId" = ? and "tblPerson"."PersonId" = ?' ,
bindings : [ 'Boonesville' , 1 , 5 ]
} ,
2014-08-27 10:10:20 +02:00
default : {
sql : 'update "tblPerson" set "tblPerson"."City" = ? where "tblPersonData"."DataId" = ? and "tblPerson"."PersonId" = ?' ,
2014-08-26 17:16:46 +02:00
bindings : [ 'Boonesville' , 1 , 5 ]
}
} ) ;
2014-04-21 22:15:06 -04:00
} ) ;
2014-04-21 23:24:57 -04:00
it ( 'does crazy advanced inserts with clever raw use, #211' , function ( ) {
2014-08-26 17:16:46 +02:00
if ( clientName === 'sqlite3' ) {
// TODO: THIS IS NOT WORKING
console . log ( "This tests fails with SQLite3" ) ;
return ;
}
var q1 = qb ( ) . select ( raw ( "'user'" ) , raw ( "'user@foo.com'" ) ) . whereNotExists ( function ( ) {
2014-04-21 23:24:57 -04:00
this . select ( 1 ) . from ( 'recipients' ) . where ( 'recipient_id' , 1 ) ;
} ) . toSQL ( ) ;
2014-08-26 17:16:46 +02:00
var q2 = qb ( ) . table ( 'recipients' ) . insert ( raw ( '(recipient_id, email) ' + q1 . sql , q1 . bindings ) ) ;
testsql ( q2 , {
mysql : {
sql : 'insert into `recipients` (recipient_id, email) select \'user\', \'user@foo.com\' where not exists (select 1 from `recipients` where `recipient_id` = ?)' ,
bindings : [ 1 ]
} ,
default : {
sql : 'insert into "recipients" (recipient_id, email) select \'user\', \'user@foo.com\' where not exists (select 1 from "recipients" where "recipient_id" = ?)' ,
bindings : [ 1 ]
}
} ) ;
2014-04-21 23:24:57 -04:00
} ) ;
2014-06-30 12:42:33 -04:00
it ( 'supports capitalized operators' , function ( ) {
2014-08-26 17:16:46 +02:00
testsql ( qb ( ) . select ( '*' ) . from ( 'users' ) . where ( 'name' , 'LIKE' , '%test%' ) , {
mysql : {
sql : 'select * from `users` where `name` LIKE ?' ,
bindings : [ '%test%' ]
} ,
default : {
sql : 'select * from "users" where "name" LIKE ?' ,
bindings : [ '%test%' ]
}
} ) ;
2014-06-30 12:42:33 -04:00
} ) ;
2014-05-09 14:42:29 -04:00
it ( 'throws if you try to use an invalid operator' , function ( ) {
var err ;
try {
2014-08-26 17:16:46 +02:00
qb ( ) . select ( '*' ) . where ( 'id' , 'isnt' , 1 ) . toString ( ) ;
2014-05-09 14:42:29 -04:00
} catch ( e ) {
err = e . message ;
}
expect ( err ) . to . equal ( "The operator \"isnt\" is not permitted" ) ;
} ) ;
it ( 'throws if you try to use an invalid operator in an inserted statement' , function ( ) {
2014-08-26 17:16:46 +02:00
var err , obj = qb ( ) . select ( '*' ) . where ( 'id' , 'isnt' , 1 ) ;
2014-05-09 14:42:29 -04:00
try {
2014-08-26 17:16:46 +02:00
qb ( ) . select ( '*' ) . from ( 'users' ) . where ( 'id' , 'in' , obj ) . toString ( ) ;
2014-05-09 14:42:29 -04:00
} catch ( e ) {
err = e . message ;
}
expect ( err ) . to . equal ( "The operator \"isnt\" is not permitted" ) ;
} ) ;
2014-05-29 13:40:34 -04:00
it ( "#287 - wraps correctly for arrays" , function ( ) {
2014-08-26 17:16:46 +02:00
// arrays only work for postgres
testsql ( qb ( ) . select ( '*' ) . from ( 'value' ) . join ( 'table' , 'table.array_column[1]' , '=' , raw ( '?' , 1 ) ) , {
mysql : {
sql : 'select * from `value` inner join `table` on `table`.`array_column[1]` = ?' ,
bindings : [ 1 ]
} ,
postgres : {
sql : 'select * from "value" inner join "table" on "table"."array_column"[1] = ?' ,
bindings : [ 1 ]
} ,
default : {
sql : 'select * from "value" inner join "table" on "table"."array_column[1]" = ?' ,
bindings : [ 1 ]
}
} ) ;
2014-05-29 13:40:34 -04:00
} ) ;
2014-06-09 15:28:22 -04:00
it ( 'allows wrap on raw to wrap in parens and alias' , function ( ) {
2014-08-26 17:16:46 +02:00
testsql ( qb ( ) . select (
2014-06-09 15:28:22 -04:00
'e.lastname' ,
'e.salary' ,
raw (
2014-08-26 17:16:46 +02:00
qb ( ) . select ( 'avg(salary)' ) . from ( 'employee' ) . whereRaw ( 'dept_no = e.dept_no' )
2014-06-09 15:28:22 -04:00
) . wrap ( '(' , ') avg_sal_dept' )
) . from ( 'employee as e' )
2014-08-26 17:16:46 +02:00
. where ( 'dept_no' , '=' , 'e.dept_no' ) , {
mysql : {
sql : 'select `e`.`lastname`, `e`.`salary`, (select `avg(salary)` from `employee` where dept_no = e.dept_no) avg_sal_dept from `employee` as `e` where `dept_no` = ?' ,
bindings : [ 'e.dept_no' ]
} ,
oracle : {
sql : 'select "e"."lastname", "e"."salary", (select "avg(salary)" from "employee" where dept_no = e.dept_no) avg_sal_dept from "employee" "e" where "dept_no" = ?' ,
bindings : [ 'e.dept_no' ]
} ,
default : {
sql : 'select "e"."lastname", "e"."salary", (select "avg(salary)" from "employee" where dept_no = e.dept_no) avg_sal_dept from "employee" as "e" where "dept_no" = ?' ,
bindings : [ 'e.dept_no' ]
}
} ) ;
2014-06-09 15:28:22 -04:00
} ) ;
2014-06-14 16:26:01 -04:00
it ( 'allows select as syntax' , function ( ) {
2014-08-26 17:16:46 +02:00
testsql ( qb ( ) . select (
2014-06-14 16:26:01 -04:00
'e.lastname' ,
'e.salary' ,
2014-08-26 17:16:46 +02:00
qb ( ) . select ( 'avg(salary)' ) . from ( 'employee' ) . whereRaw ( 'dept_no = e.dept_no' ) . as ( 'avg_sal_dept' )
2014-06-14 16:26:01 -04:00
) . from ( 'employee as e' )
2014-08-26 17:16:46 +02:00
. where ( 'dept_no' , '=' , 'e.dept_no' ) , {
mysql : {
sql : 'select `e`.`lastname`, `e`.`salary`, (select `avg(salary)` from `employee` where dept_no = e.dept_no) as `avg_sal_dept` from `employee` as `e` where `dept_no` = ?' ,
bindings : [ "e.dept_no" ]
} ,
oracle : {
// TODO: Check if possible
sql : 'select "e"."lastname", "e"."salary", (select "avg(salary)" from "employee" where dept_no = e.dept_no) "avg_sal_dept" from "employee" "e" where "dept_no" = ?' ,
bindings : [ "e.dept_no" ]
} ,
default : {
sql : 'select "e"."lastname", "e"."salary", (select "avg(salary)" from "employee" where dept_no = e.dept_no) as "avg_sal_dept" from "employee" as "e" where "dept_no" = ?' ,
bindings : [ "e.dept_no" ]
2014-08-27 10:10:20 +02:00
}
2014-08-26 17:16:46 +02:00
} ) ;
2014-06-14 16:26:01 -04:00
} ) ;
it ( 'allows function for subselect column' , function ( ) {
2014-08-26 17:16:46 +02:00
testsql ( qb ( ) . select (
2014-06-14 16:26:01 -04:00
'e.lastname' ,
'e.salary'
) . select ( function ( ) {
this . select ( 'avg(salary)' ) . from ( 'employee' ) . whereRaw ( 'dept_no = e.dept_no' ) . as ( 'avg_sal_dept' ) ;
} ) . from ( 'employee as e' )
2014-08-26 17:16:46 +02:00
. where ( 'dept_no' , '=' , 'e.dept_no' ) , {
mysql : {
sql : 'select `e`.`lastname`, `e`.`salary`, (select `avg(salary)` from `employee` where dept_no = e.dept_no) as `avg_sal_dept` from `employee` as `e` where `dept_no` = ?' ,
bindings : [ "e.dept_no" ]
} ,
oracle : {
// TODO: Check if possible
sql : 'select "e"."lastname", "e"."salary", (select "avg(salary)" from "employee" where dept_no = e.dept_no) "avg_sal_dept" from "employee" "e" where "dept_no" = ?' ,
bindings : [ "e.dept_no" ]
} ,
default : {
sql : 'select "e"."lastname", "e"."salary", (select "avg(salary)" from "employee" where dept_no = e.dept_no) as "avg_sal_dept" from "employee" as "e" where "dept_no" = ?' ,
bindings : [ "e.dept_no" ]
2014-08-27 10:10:20 +02:00
}
2014-08-26 17:16:46 +02:00
} ) ;
2014-06-14 16:26:01 -04:00
} ) ;
2014-07-19 20:02:49 +10:00
it ( 'supports arbitrarily nested raws' , function ( ) {
2014-08-26 17:16:46 +02:00
var chain = qb ( ) . select ( '*' ) . from ( 'places' )
2014-07-19 20:02:49 +10:00
. where ( raw ( 'ST_DWithin((places.address).xy, ?, ?) AND ST_Distance((places.address).xy, ?) > ? AND ?' , [
raw ( 'ST_SetSRID(?,?)' , [
raw ( 'ST_MakePoint(?,?)' , [ - 10 , 10 ] ) ,
4326
] ) ,
100000 ,
raw ( 'ST_SetSRID(?,?)' , [
raw ( 'ST_MakePoint(?,?)' , [ - 5 , 5 ] ) ,
4326
] ) ,
50000 ,
raw ( 'places.id IN ?' , [ [ 1 , 2 , 3 ] ] )
2014-08-26 17:16:46 +02:00
] ) ) ;
testsql ( chain , {
mysql : {
sql : 'select * from `places` where ST_DWithin((places.address).xy, ST_SetSRID(ST_MakePoint(?,?),?), ?) AND ST_Distance((places.address).xy, ST_SetSRID(ST_MakePoint(?,?),?)) > ? AND places.id IN ?' ,
bindings : [ - 10 , 10 , 4326 , 100000 , - 5 , 5 , 4326 , 50000 , [ 1 , 2 , 3 ] ]
} ,
default : {
sql : 'select * from "places" where ST_DWithin((places.address).xy, ST_SetSRID(ST_MakePoint(?,?),?), ?) AND ST_Distance((places.address).xy, ST_SetSRID(ST_MakePoint(?,?),?)) > ? AND places.id IN ?' ,
bindings : [ - 10 , 10 , 4326 , 100000 , - 5 , 5 , 4326 , 50000 , [ 1 , 2 , 3 ] ]
}
} ) ;
2014-07-19 20:02:49 +10:00
} ) ;
2014-08-14 18:02:50 -04:00
it ( 'has joinRaw for arbitrary join clauses' , function ( ) {
2014-08-26 17:16:46 +02:00
testsql ( qb ( ) . select ( '*' ) . from ( 'accounts' ) . joinRaw ( 'natural full join table1' ) . where ( 'id' , 1 ) , {
mysql : {
sql : 'select * from `accounts` natural full join table1 where `id` = ?' ,
bindings : [ 1 ]
} ,
default : {
sql : 'select * from "accounts" natural full join table1 where "id" = ?' ,
bindings : [ 1 ]
}
} ) ;
2014-08-14 18:02:50 -04:00
} ) ;
it ( 'accepts a knex.raw for arbitrary join clauses' , function ( ) {
2014-08-26 17:16:46 +02:00
testsql ( qb ( ) . select ( '*' ) . from ( 'accounts' ) . join ( raw ( 'natural full join table1' ) ) . where ( 'id' , 1 ) , {
mysql : {
sql : 'select * from `accounts` natural full join table1 where `id` = ?' ,
bindings : [ 1 ]
} ,
default : {
sql : 'select * from "accounts" natural full join table1 where "id" = ?' ,
bindings : [ 1 ]
}
} ) ;
2014-08-14 18:02:50 -04:00
} ) ;
2014-08-24 14:50:29 -04:00
it ( 'allows sub-query function on insert, #427' , function ( ) {
2014-08-26 17:16:46 +02:00
testsql ( qb ( ) . into ( 'votes' ) . insert ( function ( ) {
2014-08-24 14:50:29 -04:00
this . select ( '*' ) . from ( 'votes' ) . where ( 'id' , 99 ) ;
2014-08-26 17:16:46 +02:00
} ) , {
mysql : {
sql : 'insert into `votes` select * from `votes` where `id` = ?' ,
bindings : [ 99 ]
} ,
sqlite3 : {
// TODO: THIS IS MAYBE WRONG
sql : "insert into \"votes\" default values" ,
2014-08-27 10:10:20 +02:00
bindings : [ ]
2014-08-26 17:16:46 +02:00
} ,
default : {
sql : 'insert into "votes" select * from "votes" where "id" = ?' ,
bindings : [ 99 ]
}
} ) ;
2014-08-24 14:50:29 -04:00
} ) ;
it ( 'allows sub-query chain on insert, #427' , function ( ) {
2014-08-26 17:16:46 +02:00
if ( clientName === 'sqlite3' ) {
// TODO: THIS IS NOT WORKING
console . log ( "This tests fails with SQLite3" ) ;
return ;
}
testsql ( qb ( ) . into ( 'votes' ) . insert ( qb ( ) . select ( '*' ) . from ( 'votes' ) . where ( 'id' , 99 ) ) , {
mysql : {
sql : 'insert into `votes` select * from `votes` where `id` = ?' ,
bindings : [ 99 ]
} ,
oracle : {
sql : 'insert into "votes" select * from "votes" where "id" = ?' ,
bindings : [ 99 ]
} ,
default : {
sql : 'insert into "votes" select * from "votes" where "id" = ?' ,
bindings : [ 99 ]
}
2014-08-27 10:10:20 +02:00
} ) ;
2014-08-24 14:50:29 -04:00
} ) ;
2013-12-27 14:44:21 -05:00
} ) ;
2014-08-21 23:39:12 +02:00
} ;