From 6481a46f2b5cfbdb748a212205b1470dc0313328 Mon Sep 17 00:00:00 2001 From: Eric Peterson Date: Wed, 6 Nov 2024 12:26:17 -0700 Subject: [PATCH] feat(QueryUtils): Auto boolean casting MIME-Version: 1.0 Content-Type: text/plain; charset=UTF-8 Content-Transfer-Encoding: 8bit Grammars will be able to influence the `cfsqltype` and value when passing in a literal boolean value as a binding. Postgres and SQLite have boolean support, so they will keep the literal boolean value and use a `cfsqltype` of `CF_SQL_OTHER`. SQL Server uses `CF_SQL_BIT`, Oracle users `CF_SQL_NUMERIC`, and MySQL uses `CF_SQL_TINYINT` — all of these will convert literal boolean values to either 1 or 0. This behavior is skipped when providing a custom `cfsqltype`. Custom grammars can implement the `getBooleanSqlType` and `convertBooleanValue` methods to customize this behavior. BREAKING CHANGE: Previously, literal boolean values would be converted and treated as `CF_SQL_VARCHAR`. Now they will be converted depending on the grammar. Additionally, attempting to change the grammar with any bindings currently configured will throw an exception. This is because the bindings are converted via the grammar when added to the builder and cannot be changed retroactively when setting a new grammar. Set the grammar first before configuring the query to avoid this exception. --- models/Grammars/BaseGrammar.cfc | 15 ++ models/Grammars/OracleGrammar.cfc | 4 + models/Grammars/PostgresGrammar.cfc | 8 + models/Grammars/SQLiteGrammar.cfc | 8 + models/Grammars/SqlServerGrammar.cfc | 4 + models/Query/QueryBuilder.cfc | 51 ++++--- models/Query/QueryUtils.cfc | 38 ++++- server.json | 2 +- tests/resources/AbstractQueryBuilderSpec.cfc | 46 +++++- tests/specs/Query/Abstract/QueryUtilsSpec.cfc | 144 +++++++++++++++--- tests/specs/Query/MySQLQueryBuilderSpec.cfc | 42 +++++ tests/specs/Query/OracleQueryBuilderSpec.cfc | 44 ++++++ .../specs/Query/PostgresQueryBuilderSpec.cfc | 42 +++++ tests/specs/Query/SQLiteQueryBuilderSpec.cfc | 42 +++++ .../specs/Query/SqlServerQueryBuilderSpec.cfc | 42 +++++ 15 files changed, 480 insertions(+), 52 deletions(-) diff --git a/models/Grammars/BaseGrammar.cfc b/models/Grammars/BaseGrammar.cfc index c93fe64..df4a657 100644 --- a/models/Grammars/BaseGrammar.cfc +++ b/models/Grammars/BaseGrammar.cfc @@ -1509,6 +1509,21 @@ component displayname="Grammar" accessors="true" singleton { return "TINYINT(1)"; } + public string function getBooleanSqlType() { + return "CF_SQL_TINYINT"; + } + + public any function convertBooleanValue( required any value ) { + return arguments.value ? 1 : 0; + } + + function convertToBooleanType( any value ) { + return { + "value": isNull( value ) ? javacast( "null", "" ) : convertBooleanValue( value ), + "cfsqltype": getBooleanSqlType() + }; + } + function typeChar( column ) { return "CHAR(#column.getLength()#)"; } diff --git a/models/Grammars/OracleGrammar.cfc b/models/Grammars/OracleGrammar.cfc index eb689e4..4031f2a 100644 --- a/models/Grammars/OracleGrammar.cfc +++ b/models/Grammars/OracleGrammar.cfc @@ -521,6 +521,10 @@ component extends="qb.models.Grammars.BaseGrammar" singleton { return "NUMBER(1, 0)"; } + public string function getBooleanSqlType() { + return "CF_SQL_NUMERIC"; + } + function typeDatetime( column ) { return typeTimestamp( column ); } diff --git a/models/Grammars/PostgresGrammar.cfc b/models/Grammars/PostgresGrammar.cfc index 02fbf53..e82c188 100644 --- a/models/Grammars/PostgresGrammar.cfc +++ b/models/Grammars/PostgresGrammar.cfc @@ -463,6 +463,14 @@ component extends="qb.models.Grammars.BaseGrammar" singleton { return "BOOLEAN"; } + public string function getBooleanSqlType() { + return "CF_SQL_OTHER"; + } + + public any function convertBooleanValue( required any value ) { + return !!arguments.value; + } + function typeDatetime( column ) { return typeTimestamp( column ); } diff --git a/models/Grammars/SQLiteGrammar.cfc b/models/Grammars/SQLiteGrammar.cfc index d1b0929..2f95ed5 100644 --- a/models/Grammars/SQLiteGrammar.cfc +++ b/models/Grammars/SQLiteGrammar.cfc @@ -278,6 +278,14 @@ component extends="qb.models.Grammars.BaseGrammar" singleton { return "BOOLEAN"; } + public string function getBooleanSqlType() { + return "CF_SQL_OTHER"; + } + + public any function convertBooleanValue( required any value ) { + return !!arguments.value; + } + function typeChar( column ) { return "VARCHAR(#column.getLength()#)"; } diff --git a/models/Grammars/SqlServerGrammar.cfc b/models/Grammars/SqlServerGrammar.cfc index ca3d13b..47f81fe 100644 --- a/models/Grammars/SqlServerGrammar.cfc +++ b/models/Grammars/SqlServerGrammar.cfc @@ -608,6 +608,10 @@ component extends="qb.models.Grammars.BaseGrammar" singleton accessors="true" { return "BIT"; } + public string function getBooleanSqlType() { + return "CF_SQL_BIT"; + } + function typeChar( column ) { return "NCHAR(#column.getLength()#)"; } diff --git a/models/Query/QueryBuilder.cfc b/models/Query/QueryBuilder.cfc index 0fb31ab..7b5bb53 100644 --- a/models/Query/QueryBuilder.cfc +++ b/models/Query/QueryBuilder.cfc @@ -808,7 +808,7 @@ component displayname="QueryBuilder" accessors="true" { if ( !arrayIsEmpty( arguments.bindings ) ) { addBindings( arguments.bindings.map( function( value ) { - return utils.extractBinding( value ); + return utils.extractBinding( value, variables.grammar ); } ), "from" ); @@ -830,7 +830,7 @@ component displayname="QueryBuilder" accessors="true" { if ( !arrayIsEmpty( arguments.bindings ) ) { addBindings( arguments.bindings.map( function( value ) { - return utils.extractBinding( value ); + return utils.extractBinding( value, variables.grammar ); } ), "from" ); @@ -1706,7 +1706,7 @@ component displayname="QueryBuilder" accessors="true" { ); if ( getUtils().isNotExpression( arguments.value ) ) { - addBindings( utils.extractBinding( arguments.value ), "where" ); + addBindings( utils.extractBinding( arguments.value, variables.grammar ), "where" ); } return this; @@ -1812,7 +1812,7 @@ component displayname="QueryBuilder" accessors="true" { var bindings = values .filter( utils.isNotExpression ) .map( function( value ) { - return utils.extractBinding( value ); + return utils.extractBinding( value, variables.grammar ); } ); addBindings( bindings, "where" ); @@ -1880,7 +1880,7 @@ component displayname="QueryBuilder" accessors="true" { public QueryBuilder function whereRaw( required string sql, array whereBindings = [], string combinator = "and" ) { addBindings( whereBindings.map( function( binding ) { - return utils.extractBinding( binding ); + return utils.extractBinding( binding, variables.grammar ); } ), "where" ); @@ -2102,8 +2102,8 @@ component displayname="QueryBuilder" accessors="true" { callback( arguments.end ); } - addBindings( utils.extractBinding( arguments.start ), "where" ); - addBindings( utils.extractBinding( arguments.end ), "where" ); + addBindings( utils.extractBinding( arguments.start, variables.grammar ), "where" ); + addBindings( utils.extractBinding( arguments.end, variables.grammar ), "where" ); if ( isStruct( arguments.start ) && !structKeyExists( arguments.start, "isBuilder" ) && arguments.start.keyExists( @@ -2231,7 +2231,7 @@ component displayname="QueryBuilder" accessors="true" { arguments.column .getBindings() .map( function( binding ) { - return utils.extractBinding( binding ); + return utils.extractBinding( binding, variables.grammar ); } ), "having" ); @@ -2261,14 +2261,14 @@ component displayname="QueryBuilder" accessors="true" { arguments.column .getBindings() .map( function( binding ) { - return utils.extractBinding( binding ); + return utils.extractBinding( binding, variables.grammar ); } ), "having" ); } if ( getUtils().isNotExpression( arguments.value ) ) { - addBindings( utils.extractBinding( arguments.value ), "having" ); + addBindings( utils.extractBinding( arguments.value, variables.grammar ), "having" ); } return this; @@ -2399,7 +2399,7 @@ component displayname="QueryBuilder" accessors="true" { column .getBindings() .map( function( value ) { - return variables.utils.extractBinding( arguments.value ); + return variables.utils.extractBinding( arguments.value, variables.grammar ); } ), "orderBy" ); @@ -2524,7 +2524,7 @@ component displayname="QueryBuilder" accessors="true" { if ( !arrayIsEmpty( arguments.bindings ) ) { addBindings( arguments.bindings.map( function( value ) { - return variables.utils.extractBinding( arguments.value ); + return variables.utils.extractBinding( arguments.value, variables.grammar ); } ), "orderBy" ); @@ -2957,7 +2957,8 @@ component displayname="QueryBuilder" accessors="true" { var newBindings = arguments.values.map( function( value ) { return columns.map( function( column ) { return getUtils().extractBinding( - value.keyExists( column.original ) ? value[ column.original ] : javacast( "null", "" ) + value.keyExists( column.original ) ? value[ column.original ] : javacast( "null", "" ), + variables.grammar ); } ); } ); @@ -3073,7 +3074,8 @@ component displayname="QueryBuilder" accessors="true" { var newBindings = arguments.values.map( function( value ) { return columns.map( function( column ) { return getUtils().extractBinding( - value.keyExists( column.original ) ? value[ column.original ] : javacast( "null", "" ) + value.keyExists( column.original ) ? value[ column.original ] : javacast( "null", "" ), + variables.grammar ); } ); } ); @@ -3160,7 +3162,7 @@ component displayname="QueryBuilder" accessors="true" { arguments.values[ column.original ] = value; addBindings( value.getBindings(), "update" ); } else if ( !getUtils().isExpression( value ) ) { - addBindings( getUtils().extractBinding( value ), "update" ); + addBindings( getUtils().extractBinding( value, variables.grammar ), "update" ); } } @@ -3295,7 +3297,8 @@ component displayname="QueryBuilder" accessors="true" { newInsertBindings = arguments.values.map( function( value ) { return columns.map( function( column ) { return getUtils().extractBinding( - value.keyExists( column.original ) ? value[ column.original ] : javacast( "null", "" ) + value.keyExists( column.original ) ? value[ column.original ] : javacast( "null", "" ), + variables.grammar ); } ); } ); @@ -3635,7 +3638,7 @@ component displayname="QueryBuilder" accessors="true" { */ public boolean function existsOrFail( struct options = {}, any errorMessage ) { if ( !this.exists( arguments.options ) ) { - param arguments.errorMessage = "No rows found with constraints [#variables.utils.serializeBindings( this.getBindings() )#]"; + param arguments.errorMessage = "No rows found with constraints [#variables.utils.serializeBindings( this.getBindings(), variables.grammar )#]"; throw( type = "RecordNotFound", message = arguments.errorMessage ); } return true; @@ -3699,7 +3702,7 @@ component displayname="QueryBuilder" accessors="true" { public any function firstOrFail( any errorMessage, struct options = {} ) { var result = first( arguments.options ); if ( structIsEmpty( result ) ) { - param arguments.errorMessage = "No rows found with constraints [#variables.utils.serializeBindings( this.getBindings() )#]"; + param arguments.errorMessage = "No rows found with constraints [#variables.utils.serializeBindings( this.getBindings(), variables.grammar )#]"; if ( isClosure( arguments.errorMessage ) || isCustomFunction( arguments.errorMessage ) ) { arguments.errorMessage = arguments.errorMessage( this ); } @@ -4416,4 +4419,16 @@ component displayname="QueryBuilder" accessors="true" { return isSimpleValue( column ) ? variables.columnFormatter( column ) : column; } + public QueryBuilder function setGrammar( required BaseGrammar grammar ) { + if ( !this.getBindings().isEmpty() ) { + throw( + type = "QBSetGrammarWithBindingsError", + message = "You cannot switch grammars after adding bindings. Please set the grammar before adding bindings.", + detail = "The easiest way to fix this error is to set the grammar before any other actions on the query builder." + ); + } + variables.grammar = arguments.grammar; + return this; + } + } diff --git a/models/Query/QueryUtils.cfc b/models/Query/QueryUtils.cfc index d253d0c..e7e4798 100644 --- a/models/Query/QueryUtils.cfc +++ b/models/Query/QueryUtils.cfc @@ -84,7 +84,7 @@ component singleton displayname="QueryUtils" accessors="true" { * * @return any */ - public any function extractBinding( any value ) { + public any function extractBinding( any value, required BaseGrammar grammar ) { if ( isNull( arguments.value ) ) { return { "cfsqltype": "CF_SQL_VARCHAR", "value": "", "null": true }; } @@ -104,7 +104,11 @@ component singleton displayname="QueryUtils" accessors="true" { } if ( !structKeyExists( binding, "cfsqltype" ) ) { - binding.cfsqltype = inferSqlType( binding.value ); + if ( checkIsActuallyBoolean( binding.value ) ) { + structAppend( binding, arguments.grammar.convertToBooleanType( binding.value ), true ); + } else { + binding.cfsqltype = inferSqlType( binding.value, arguments.grammar ); + } } if ( binding.cfsqltype == "CF_SQL_TIMESTAMP" ) { @@ -174,7 +178,7 @@ component singleton displayname="QueryUtils" accessors="true" { * * @return string */ - public string function inferSqlType( any value ) { + public string function inferSqlType( any value, required BaseGrammar grammar ) { if ( isNull( arguments.value ) ) { return "CF_SQL_VARCHAR"; } @@ -183,7 +187,7 @@ component singleton displayname="QueryUtils" accessors="true" { return arraySame( value, function( val ) { - return inferSqlType( val ); + return inferSqlType( val, grammar ); }, "CF_SQL_VARCHAR" ); @@ -201,6 +205,10 @@ component singleton displayname="QueryUtils" accessors="true" { return "CF_SQL_TIMESTAMP"; } + if ( checkIsActuallyBoolean( value ) ) { + return arguments.grammar.getBooleanSqlType(); + } + return "CF_SQL_VARCHAR"; } @@ -514,6 +522,24 @@ component singleton displayname="QueryUtils" accessors="true" { } } + /** + * Detects if value is a Boolean based on className + * + * @value The value + * + * @return boolean + */ + private boolean function checkIsActuallyBoolean( any value ) { + if ( isNull( arguments.value ) ) { + return false; + } + + return arrayContainsNoCase( + [ "CFBoolean", "Boolean" ], + listLast( toString( getMetadata( arguments.value ) ), "." ) + ); + } + /** Utility functions to assist with preventing duplicate joins. Adapted from cflib.org **/ /** @@ -615,10 +641,10 @@ component singleton displayname="QueryUtils" accessors="true" { return true; } - public string function serializeBindings( required array bindings ) { + public string function serializeBindings( required array bindings, required BaseGrammar grammar ) { return serializeJSON( arguments.bindings.map( function( binding ) { - var newBinding = extractBinding( duplicate( binding ) ); + var newBinding = extractBinding( duplicate( binding ), grammar ); if ( isBinary( newBinding.value ) ) { newBinding.value = toBase64( newBinding.value ); } diff --git a/server.json b/server.json index 9b9ddae..6ac7dad 100644 --- a/server.json +++ b/server.json @@ -6,7 +6,7 @@ } }, "app":{ - "cfengine":"boxlang@be" + "cfengine":"lucee@^5" }, "directoryBrowsing":"true", "JVM":{ diff --git a/tests/resources/AbstractQueryBuilderSpec.cfc b/tests/resources/AbstractQueryBuilderSpec.cfc index 58414e9..e134c1a 100644 --- a/tests/resources/AbstractQueryBuilderSpec.cfc +++ b/tests/resources/AbstractQueryBuilderSpec.cfc @@ -498,6 +498,19 @@ component extends="testbox.system.BaseSpec" { ); }, whereBuilderInstance() ); } ); + + it( "can add a where statement with a boolean literal", function() { + testCase( + callback = function( builder ) { + builder + .select( "*" ) + .from( "users" ) + .where( "active", "=", true ); + }, + expected = whereBoolean(), + withFullBindings = true + ); + } ); } ); describe( "where exists", function() { @@ -2241,6 +2254,31 @@ component extends="testbox.system.BaseSpec" { }, insertSingleColumn() ); } ); + it( "correctly formats booleans during an insert", function() { + testCase( + callback = function( builder ) { + return builder.from( "users" ).insert( values = { "active": true }, toSql = true ); + }, + expected = insertBoolean(), + withFullBindings = true + ); + } ); + + it( "always uses passed in cfsqltypes if available", function() { + testCase( + callback = function( builder ) { + return builder + .from( "users" ) + .insert( + values = { "active": { "value": true, "cfsqltype": "CF_SQL_BOOLEAN" } }, + toSql = true + ); + }, + expected = insertBooleanExplicitSqlType(), + withFullBindings = true + ); + } ); + it( "can insert a struct of data with multiple columns into a table", function() { testCase( function( builder ) { return builder @@ -2773,7 +2811,7 @@ component extends="testbox.system.BaseSpec" { } ); } - private function testCase( callback, expected ) { + private function testCase( required function callback, required any expected, boolean withFullBindings = false ) { try { var builder = getBuilder(); var sql = callback( builder ); @@ -2789,7 +2827,7 @@ component extends="testbox.system.BaseSpec" { } expect( sql ).toBeWithCase( expected.sql ); - expect( getTestBindings( builder ) ).toBe( expected.bindings ); + expect( getTestBindings( builder, arguments.withFullBindings ) ).toBe( expected.bindings ); } catch ( any e ) { if ( !isSimpleValue( expected ) && structKeyExists( expected, "exception" ) ) { expect( e.type ).toBe( expected.exception ); @@ -2803,7 +2841,7 @@ component extends="testbox.system.BaseSpec" { throw( "Must be implemented in a subclass" ); } - private array function getTestBindings( builder ) { + private array function getTestBindings( required QueryBuilder builder, boolean withFullBindings = false ) { return builder .getBindings() .map( function( binding ) { @@ -2813,7 +2851,7 @@ component extends="testbox.system.BaseSpec" { if ( binding.null ) { return "NULL"; } else { - return binding.value; + return withFullBindings ? binding : binding.value; } } } ); diff --git a/tests/specs/Query/Abstract/QueryUtilsSpec.cfc b/tests/specs/Query/Abstract/QueryUtilsSpec.cfc index ee18079..d948fc2 100644 --- a/tests/specs/Query/Abstract/QueryUtilsSpec.cfc +++ b/tests/specs/Query/Abstract/QueryUtilsSpec.cfc @@ -12,41 +12,41 @@ component displayname="QueryUtilsSpec" extends="testbox.system.BaseSpec" { function run() { describe( "inferSqlType()", function() { it( "strings", function() { - expect( utils.inferSqlType( "a string" ) ).toBe( "CF_SQL_VARCHAR" ); + expect( utils.inferSqlType( "a string", variables.mockGrammar ) ).toBe( "CF_SQL_VARCHAR" ); } ); describe( "numbers", function() { it( "integers", function() { - expect( utils.inferSqlType( 100 ) ).toBe( "CF_SQL_INTEGER" ); + expect( utils.inferSqlType( 100, variables.mockGrammar ) ).toBe( "CF_SQL_INTEGER" ); variables.utils.setAutoDeriveNumericType( false ); - expect( utils.inferSqlType( 100 ) ).toBe( "CF_SQL_NUMERIC" ); + expect( utils.inferSqlType( 100, variables.mockGrammar ) ).toBe( "CF_SQL_NUMERIC" ); variables.utils.setAutoDeriveNumericType( true ); } ); it( "decimals", function() { - expect( utils.inferSqlType( 4.50 ) ).toBe( "CF_SQL_DECIMAL" ); + expect( utils.inferSqlType( 4.50, variables.mockGrammar ) ).toBe( "CF_SQL_DECIMAL" ); variables.utils.setAutoDeriveNumericType( false ); - expect( utils.inferSqlType( 4.50 ) ).toBe( "CF_SQL_NUMERIC" ); + expect( utils.inferSqlType( 4.50, variables.mockGrammar ) ).toBe( "CF_SQL_NUMERIC" ); variables.utils.setAutoDeriveNumericType( true ); } ); it( "really long decimals", function() { variables.utils.setAutoDeriveNumericType( true ); - expect( utils.inferSqlType( 19482.279999997998 ) ).toBe( "CF_SQL_DECIMAL" ); + expect( utils.inferSqlType( 19482.279999997998, variables.mockGrammar ) ).toBe( "CF_SQL_DECIMAL" ); } ); } ); it( "dates", function() { - expect( utils.inferSqlType( now() ) ).toBe( "CF_SQL_TIMESTAMP" ); + expect( utils.inferSqlType( now(), variables.mockGrammar ) ).toBe( "CF_SQL_TIMESTAMP" ); variables.utils.setStrictDateDetection( true ); - // expect( utils.inferSqlType( now() ) ).toBe( "CF_SQL_TIMESTAMP" ); - // expect( utils.inferSqlType( "06 12345" ) ).toBe( "CF_SQL_VARCHAR" ); + // expect( utils.inferSqlType( now(), variables.mockGrammar ) ).toBe( "CF_SQL_TIMESTAMP" ); + // expect( utils.inferSqlType( "06 12345" ), variables.mockGrammar ).toBe( "CF_SQL_VARCHAR" ); variables.utils.setStrictDateDetection( false ); } ); it( "null", function() { - expect( utils.inferSqlType( javacast( "null", "" ) ) ).toBe( "CF_SQL_VARCHAR" ); - expect( utils.extractBinding( javacast( "null", "" ) ) ).toBe( { "null": true, "cfsqltype": "CF_SQL_VARCHAR", "value": "" } ); + expect( utils.inferSqlType( javacast( "null", "" ), variables.mockGrammar ) ).toBe( "CF_SQL_VARCHAR" ); + expect( utils.extractBinding( javacast( "null", "" ), variables.mockGrammar ) ).toBe( { "null": true, "cfsqltype": "CF_SQL_VARCHAR", "value": "" } ); makePublic( utils, "checkIsActuallyNumeric", "publicCheckIsActuallyNumeric" ); expect( utils.publicCheckIsActuallyNumeric( javacast( "null", "" ) ) ).toBe( false ); makePublic( utils, "isFloatingPoint", "publicIsFloatingPoint" ); @@ -61,19 +61,105 @@ component displayname="QueryUtilsSpec" extends="testbox.system.BaseSpec" { ).toBe( 0 ); } ); + describe( "boolean", () => { + it( "infers boolean types correctly", () => { + makePublic( utils, "checkIsActuallyBoolean", "publicCheckIsActuallyBoolean" ); + expect( utils.publicCheckIsActuallyBoolean( true ) ).toBeTrue(); + expect( utils.publicCheckIsActuallyBoolean( "true" ) ).toBeFalse(); + expect( utils.publicCheckIsActuallyBoolean( false ) ).toBeTrue(); + expect( utils.publicCheckIsActuallyBoolean( "false" ) ).toBeFalse(); + } ); + + describe( "extracting boolean params", () => { + afterEach( () => variables.mockGrammar.$reset() ); + + it( "without boolean support in the grammar", () => { + expect( utils.inferSqlType( true, variables.mockGrammar ) ).toBe( "CF_SQL_TINYINT" ); + expect( utils.inferSqlType( "true", variables.mockGrammar ) ).toBe( "CF_SQL_VARCHAR" ); + expect( utils.inferSqlType( false, variables.mockGrammar ) ).toBe( "CF_SQL_TINYINT" ); + expect( utils.inferSqlType( "false", variables.mockGrammar ) ).toBe( "CF_SQL_VARCHAR" ); + + expect( utils.extractBinding( true, variables.mockGrammar ) ).toBe( { + "list": false, + "null": false, + "cfsqltype": "CF_SQL_TINYINT", + "value": 1 + } ); + expect( utils.extractBinding( "true", variables.mockGrammar ) ).toBe( { + "list": false, + "null": false, + "cfsqltype": "CF_SQL_VARCHAR", + "value": "true" + } ); + expect( utils.extractBinding( false, variables.mockGrammar ) ).toBe( { + "list": false, + "null": false, + "cfsqltype": "CF_SQL_TINYINT", + "value": 0 + } ); + expect( utils.extractBinding( "false", variables.mockGrammar ) ).toBe( { + "list": false, + "null": false, + "cfsqltype": "CF_SQL_VARCHAR", + "value": "false" + } ); + } ); + + it( "with boolean support in the grammar", () => { + variables.mockGrammar.$( "getBooleanSqlType", "CF_SQL_OTHER" ); + variables.mockGrammar + .$( "convertToBooleanType" ) + .$callback( ( any value ) => { + return { + "value": isNull( value ) ? javacast( "null", "" ) : !!value, + "cfsqltype": "CF_SQL_OTHER" + }; + } ); + + expect( utils.extractBinding( true, variables.mockGrammar ) ).toBe( { + "list": false, + "null": false, + "cfsqltype": "CF_SQL_OTHER", + "value": true + } ); + expect( utils.extractBinding( "true", variables.mockGrammar ) ).toBe( { + "list": false, + "null": false, + "cfsqltype": "CF_SQL_VARCHAR", + "value": "true" + } ); + expect( utils.extractBinding( false, variables.mockGrammar ) ).toBe( { + "list": false, + "null": false, + "cfsqltype": "CF_SQL_OTHER", + "value": false + } ); + expect( utils.extractBinding( "false", variables.mockGrammar ) ).toBe( { + "list": false, + "null": false, + "cfsqltype": "CF_SQL_VARCHAR", + "value": "false" + } ); + } ); + } ); + } ); + describe( "it infers the sql type from the members of an array", function() { it( "if all the members of the array are the same", function() { - expect( utils.inferSqlType( [ 1, 2 ] ) ).toBe( "CF_SQL_INTEGER" ); + expect( utils.inferSqlType( [ 1, 2 ], variables.mockGrammar ) ).toBe( "CF_SQL_INTEGER" ); } ); it( "but defaults to CF_SQL_VARCHAR if they are different", function() { expect( - utils.inferSqlType( [ - 1, - 2, - 3, - dateFormat( "05/01/2016", "MM/DD/YYYY" ) - ] ) + utils.inferSqlType( + [ + 1, + 2, + 3, + dateFormat( "05/01/2016", "MM/DD/YYYY" ) + ], + variables.mockGrammar + ) ).toBe( "CF_SQL_VARCHAR" ); } ); } ); @@ -82,7 +168,7 @@ component displayname="QueryUtilsSpec" extends="testbox.system.BaseSpec" { describe( "extractBinding()", function() { it( "includes sensible defaults", function() { var datetime = parseDateTime( "05/10/2016" ); - var binding = utils.extractBinding( datetime ); + var binding = utils.extractBinding( datetime, variables.mockGrammar ); expect( binding ).toBeStruct(); expect( binding.value ).toBe( dateTimeFormat( datetime, "yyyy-mm-dd'T'HH:nn:ss.SSSXXX" ) ); @@ -92,7 +178,10 @@ component displayname="QueryUtilsSpec" extends="testbox.system.BaseSpec" { } ); it( "automatically sets a scale if needed", function() { - var binding = utils.extractBinding( { "value": 3.14159, "cfsqltype": "CF_SQL_DECIMAL" } ); + var binding = utils.extractBinding( + { "value": 3.14159, "cfsqltype": "CF_SQL_DECIMAL" }, + variables.mockGrammar + ); expect( binding ).toBeStruct(); expect( binding.value ).toBe( 3.14159 ); @@ -104,7 +193,10 @@ component displayname="QueryUtilsSpec" extends="testbox.system.BaseSpec" { } ); it( "does not set a scale for integers", function() { - var binding = utils.extractBinding( { "value": 3.14159, "cfsqltype": "CF_SQL_INTEGER" } ); + var binding = utils.extractBinding( + { "value": 3.14159, "cfsqltype": "CF_SQL_INTEGER" }, + variables.mockGrammar + ); expect( binding ).toBeStruct(); expect( binding.value ).toBe( 3.14159 ); @@ -117,7 +209,10 @@ component displayname="QueryUtilsSpec" extends="testbox.system.BaseSpec" { it( "does not set a scale when autoSetScale is set to false", function() { try { utils.setAutoAddScale( false ); - var binding = utils.extractBinding( { "value": 3.14159, "cfsqltype": "CF_SQL_DECIMAL" } ); + var binding = utils.extractBinding( + { "value": 3.14159, "cfsqltype": "CF_SQL_DECIMAL" }, + variables.mockGrammar + ); expect( binding ).toBeStruct(); expect( binding.value ).toBe( 3.14159 ); @@ -131,7 +226,10 @@ component displayname="QueryUtilsSpec" extends="testbox.system.BaseSpec" { } ); it( "uses a passed in scale if provided", function() { - var binding = utils.extractBinding( { "value": 3.14159, "cfsqltype": "CF_SQL_DECIMAL", "scale": 2 } ); + var binding = utils.extractBinding( + { "value": 3.14159, "cfsqltype": "CF_SQL_DECIMAL", "scale": 2 }, + variables.mockGrammar + ); expect( binding ).toBeStruct(); expect( binding.value ).toBe( 3.14159 ); diff --git a/tests/specs/Query/MySQLQueryBuilderSpec.cfc b/tests/specs/Query/MySQLQueryBuilderSpec.cfc index 0d2b37d..bac3670 100644 --- a/tests/specs/Query/MySQLQueryBuilderSpec.cfc +++ b/tests/specs/Query/MySQLQueryBuilderSpec.cfc @@ -207,6 +207,20 @@ component extends="tests.resources.AbstractQueryBuilderSpec" { }; } + function whereBoolean() { + return { + sql: "SELECT * FROM `users` WHERE `active` = ?", + bindings: [ + { + "cfsqltype": "CF_SQL_TINYINT", + "value": 1, + "list": false, + "null": false + } + ] + }; + } + function whereExists() { return "SELECT * FROM `orders` WHERE EXISTS (SELECT 1 FROM `products` WHERE `products`.`id` = `orders`.`id`)"; } @@ -690,6 +704,34 @@ component extends="tests.resources.AbstractQueryBuilderSpec" { return { sql: "INSERT INTO `users` (`email`) VALUES (?)", bindings: [ "foo" ] }; } + function insertBoolean() { + return { + sql: "INSERT INTO `users` (`active`) VALUES (?)", + bindings: [ + { + "value": 1, + "cfsqltype": "CF_SQL_TINYINT", + "null": false, + "list": false + } + ] + }; + } + + function insertBooleanExplicitSqlType() { + return { + sql: "INSERT INTO `users` (`active`) VALUES (?)", + bindings: [ + { + "value": true, + "cfsqltype": "CF_SQL_BOOLEAN", + "null": false, + "list": false + } + ] + }; + } + function insertMultipleColumns() { return { sql: "INSERT INTO `users` (`email`, `name`) VALUES (?, ?)", bindings: [ "foo", "bar" ] }; } diff --git a/tests/specs/Query/OracleQueryBuilderSpec.cfc b/tests/specs/Query/OracleQueryBuilderSpec.cfc index 325369a..f31bbbc 100644 --- a/tests/specs/Query/OracleQueryBuilderSpec.cfc +++ b/tests/specs/Query/OracleQueryBuilderSpec.cfc @@ -216,6 +216,21 @@ component extends="tests.resources.AbstractQueryBuilderSpec" { }; } + function whereBoolean() { + return { + sql: "SELECT * FROM ""USERS"" WHERE ""ACTIVE"" = ?", + bindings: [ + { + "cfsqltype": "CF_SQL_NUMERIC", + "value": 1, + "scale": 1, + "list": false, + "null": false + } + ] + }; + } + function whereExists() { return "SELECT * FROM ""ORDERS"" WHERE EXISTS (SELECT 1 FROM ""PRODUCTS"" WHERE ""PRODUCTS"".""ID"" = ""ORDERS"".""ID"")"; } @@ -703,6 +718,35 @@ component extends="tests.resources.AbstractQueryBuilderSpec" { return { sql: "INSERT INTO ""USERS"" (""EMAIL"") VALUES (?)", bindings: [ "foo" ] }; } + function insertBoolean() { + return { + sql: "INSERT INTO ""USERS"" (""ACTIVE"") VALUES (?)", + bindings: [ + { + "value": 1, + "cfsqltype": "CF_SQL_NUMERIC", + "scale": 1, + "null": false, + "list": false + } + ] + }; + } + + function insertBooleanExplicitSqlType() { + return { + sql: "INSERT INTO ""USERS"" (""ACTIVE"") VALUES (?)", + bindings: [ + { + "value": true, + "cfsqltype": "CF_SQL_BOOLEAN", + "null": false, + "list": false + } + ] + }; + } + function insertMultipleColumns() { return { sql: "INSERT INTO ""USERS"" (""EMAIL"", ""NAME"") VALUES (?, ?)", bindings: [ "foo", "bar" ] }; } diff --git a/tests/specs/Query/PostgresQueryBuilderSpec.cfc b/tests/specs/Query/PostgresQueryBuilderSpec.cfc index 17da15a..11bd46b 100644 --- a/tests/specs/Query/PostgresQueryBuilderSpec.cfc +++ b/tests/specs/Query/PostgresQueryBuilderSpec.cfc @@ -210,6 +210,20 @@ component extends="tests.resources.AbstractQueryBuilderSpec" { }; } + function whereBoolean() { + return { + sql: "SELECT * FROM ""users"" WHERE ""active"" = ?", + bindings: [ + { + "cfsqltype": "CF_SQL_OTHER", + "value": true, + "list": false, + "null": false + } + ] + }; + } + function whereExists() { return "SELECT * FROM ""orders"" WHERE EXISTS (SELECT 1 FROM ""products"" WHERE ""products"".""id"" = ""orders"".""id"")"; } @@ -697,6 +711,34 @@ component extends="tests.resources.AbstractQueryBuilderSpec" { return { sql: "INSERT INTO ""users"" (""email"") VALUES (?)", bindings: [ "foo" ] }; } + function insertBoolean() { + return { + sql: "INSERT INTO ""users"" (""active"") VALUES (?)", + bindings: [ + { + "value": true, + "cfsqltype": "CF_SQL_OTHER", + "null": false, + "list": false + } + ] + }; + } + + function insertBooleanExplicitSqlType() { + return { + sql: "INSERT INTO ""users"" (""active"") VALUES (?)", + bindings: [ + { + "value": true, + "cfsqltype": "CF_SQL_BOOLEAN", + "null": false, + "list": false + } + ] + }; + } + function insertMultipleColumns() { return { sql: "INSERT INTO ""users"" (""email"", ""name"") VALUES (?, ?)", bindings: [ "foo", "bar" ] }; } diff --git a/tests/specs/Query/SQLiteQueryBuilderSpec.cfc b/tests/specs/Query/SQLiteQueryBuilderSpec.cfc index 0f41c31..fbd8c72 100644 --- a/tests/specs/Query/SQLiteQueryBuilderSpec.cfc +++ b/tests/specs/Query/SQLiteQueryBuilderSpec.cfc @@ -224,6 +224,20 @@ component extends="tests.resources.AbstractQueryBuilderSpec" { }; } + function whereBoolean() { + return { + sql: "SELECT * FROM ""users"" WHERE ""active"" = ?", + bindings: [ + { + "cfsqltype": "CF_SQL_OTHER", + "value": true, + "list": false, + "null": false + } + ] + }; + } + function whereExists() { return "SELECT * FROM ""orders"" WHERE EXISTS (SELECT 1 FROM ""products"" WHERE ""products"".""id"" = ""orders"".""id"")"; } @@ -789,6 +803,34 @@ component extends="tests.resources.AbstractQueryBuilderSpec" { return { sql: "INSERT INTO ""users"" (""email"") VALUES (?)", bindings: [ "foo" ] }; } + function insertBoolean() { + return { + sql: "INSERT INTO ""users"" (""active"") VALUES (?)", + bindings: [ + { + "value": true, + "cfsqltype": "CF_SQL_OTHER", + "null": false, + "list": false + } + ] + }; + } + + function insertBooleanExplicitSqlType() { + return { + sql: "INSERT INTO ""users"" (""active"") VALUES (?)", + bindings: [ + { + "value": true, + "cfsqltype": "CF_SQL_BOOLEAN", + "null": false, + "list": false + } + ] + }; + } + function insertMultipleColumns() { return { sql: "INSERT INTO ""users"" (""email"", ""name"") VALUES (?, ?)", bindings: [ "foo", "bar" ] }; } diff --git a/tests/specs/Query/SqlServerQueryBuilderSpec.cfc b/tests/specs/Query/SqlServerQueryBuilderSpec.cfc index 9e48efe..dadd728 100644 --- a/tests/specs/Query/SqlServerQueryBuilderSpec.cfc +++ b/tests/specs/Query/SqlServerQueryBuilderSpec.cfc @@ -207,6 +207,20 @@ component extends="tests.resources.AbstractQueryBuilderSpec" { }; } + function whereBoolean() { + return { + sql: "SELECT * FROM [users] WHERE [active] = ?", + bindings: [ + { + "cfsqltype": "CF_SQL_BIT", + "value": 1, + "list": false, + "null": false + } + ] + }; + } + function whereExists() { return "SELECT * FROM [orders] WHERE EXISTS (SELECT 1 FROM [products] WHERE [products].[id] = [orders].[id])"; } @@ -688,6 +702,34 @@ component extends="tests.resources.AbstractQueryBuilderSpec" { return { sql: "INSERT INTO [users] ([email]) VALUES (?)", bindings: [ "foo" ] }; } + function insertBoolean() { + return { + sql: "INSERT INTO [users] ([active]) VALUES (?)", + bindings: [ + { + "value": 1, + "cfsqltype": "CF_SQL_BIT", + "null": false, + "list": false + } + ] + }; + } + + function insertBooleanExplicitSqlType() { + return { + sql: "INSERT INTO [users] ([active]) VALUES (?)", + bindings: [ + { + "value": true, + "cfsqltype": "CF_SQL_BOOLEAN", + "null": false, + "list": false + } + ] + }; + } + function insertMultipleColumns() { return { sql: "INSERT INTO [users] ([email], [name]) VALUES (?, ?)", bindings: [ "foo", "bar" ] }; }