From 6238626bc1a1a9aa5a236b9376127bddf91b9bb3 Mon Sep 17 00:00:00 2001 From: Eric Peterson Date: Thu, 9 Dec 2021 13:01:45 -0700 Subject: [PATCH] feat(QueryBuilder): Add insertIgnore --- models/Grammars/BaseGrammar.cfc | 26 ++++++ models/Grammars/MySQLGrammar.cfc | 24 ++++++ models/Grammars/OracleGrammar.cfc | 3 +- models/Grammars/PostgresGrammar.cfc | 19 +++++ models/Query/QueryBuilder.cfc | 81 ++++++++++++++++++- tests/resources/AbstractQueryBuilderSpec.cfc | 12 +++ tests/specs/Query/MySQLQueryBuilderSpec.cfc | 7 ++ tests/specs/Query/OracleQueryBuilderSpec.cfc | 7 ++ .../specs/Query/PostgresQueryBuilderSpec.cfc | 7 ++ .../specs/Query/SqlServerQueryBuilderSpec.cfc | 7 ++ 10 files changed, 191 insertions(+), 2 deletions(-) diff --git a/models/Grammars/BaseGrammar.cfc b/models/Grammars/BaseGrammar.cfc index 2a786e7f..b07a9458 100644 --- a/models/Grammars/BaseGrammar.cfc +++ b/models/Grammars/BaseGrammar.cfc @@ -722,6 +722,32 @@ component displayname="Grammar" accessors="true" singleton { return trim( "INSERT INTO #wrapTable( query.getFrom() )# (#columnsString#) VALUES #placeholderString#" ); } + /** + * Compile a Builder's query into an insert string ignoring duplicate key values. + * + * @qb The Builder instance. + * @columns The array of columns into which to insert. + * @target The array of key columns to match. + * @values The array of values to insert. + * + * @return string + */ + public string function compileInsertIgnore( + required QueryBuilder qb, + required array columns, + required array target, + required array values + ) { + return compileUpsert( + arguments.qb, + arguments.columns, + arguments.values, + [], + [], + arguments.target + ); + } + /** * Compile a Builder's query into an insert using string. * diff --git a/models/Grammars/MySQLGrammar.cfc b/models/Grammars/MySQLGrammar.cfc index 2b16b50e..8d0fbfc4 100644 --- a/models/Grammars/MySQLGrammar.cfc +++ b/models/Grammars/MySQLGrammar.cfc @@ -101,6 +101,30 @@ component extends="qb.models.Grammars.BaseGrammar" singleton { return super.compileInsert( argumentCollection = arguments ); } + /** + * Compile a Builder's query into an insert string ignoring duplicate key values. + * + * @qb The Builder instance. + * @columns The array of columns into which to insert. + * @target The array of key columns to match. + * @values The array of values to insert. + * + * @return string + */ + public string function compileInsertIgnore( + required QueryBuilder qb, + required array columns, + required array target, + required array values + ) { + return replace( + compileInsert( arguments.qb, arguments.columns, arguments.values ), + "INSERT", + "INSERT IGNORE", + "one" + ); + } + public string function compileUpsert( required QueryBuilder qb, required array insertColumns, diff --git a/models/Grammars/OracleGrammar.cfc b/models/Grammars/OracleGrammar.cfc index f753971f..a2db5f6e 100644 --- a/models/Grammars/OracleGrammar.cfc +++ b/models/Grammars/OracleGrammar.cfc @@ -224,8 +224,9 @@ component extends="qb.models.Grammars.BaseGrammar" singleton { } ) .toList( ", " ); } + var updateStatement = updateList == "" ? "" : " WHEN MATCHED THEN UPDATE SET #updateList#"; - return "MERGE INTO #wrapTable( arguments.qb.getFrom() )# ""QB_TARGET"" USING (#placeholderString#) ""QB_SRC"" ON #constraintString# WHEN MATCHED THEN UPDATE SET #updateList# WHEN NOT MATCHED THEN INSERT (#columnsString#) VALUES (#valuesString#)"; + return "MERGE INTO #wrapTable( arguments.qb.getFrom() )# ""QB_TARGET"" USING (#placeholderString#) ""QB_SRC"" ON #constraintString##updateStatement# WHEN NOT MATCHED THEN INSERT (#columnsString#) VALUES (#valuesString#)"; } /** diff --git a/models/Grammars/PostgresGrammar.cfc b/models/Grammars/PostgresGrammar.cfc index b9c94520..06bcda52 100644 --- a/models/Grammars/PostgresGrammar.cfc +++ b/models/Grammars/PostgresGrammar.cfc @@ -56,6 +56,25 @@ component extends="qb.models.Grammars.BaseGrammar" singleton { return super.compileInsert( argumentCollection = arguments ) & returningClause; } + /** + * Compile a Builder's query into an insert string ignoring duplicate key values. + * + * @qb The Builder instance. + * @columns The array of columns into which to insert. + * @target The array of key columns to match. + * @values The array of values to insert. + * + * @return string + */ + public string function compileInsertIgnore( + required QueryBuilder qb, + required array columns, + required array target, + required array values + ) { + return compileInsert( arguments.qb, arguments.columns, arguments.values ) & " ON CONFLICT DO NOTHING"; + } + /** * Compile a Builder's query into an update string. * diff --git a/models/Query/QueryBuilder.cfc b/models/Query/QueryBuilder.cfc index cb2f70fc..6e76dcc6 100644 --- a/models/Query/QueryBuilder.cfc +++ b/models/Query/QueryBuilder.cfc @@ -2569,7 +2569,86 @@ component displayname="QueryBuilder" accessors="true" { return runQuery( sql, arguments.options, "result" ); } - function returning( required any columns ) { + /** + * Inserts data into a table ignoring any duplicate keys when inserting. + * This call must come after setting the query's table using `from` or `table`. + * + * @values A struct or array of structs to insert in to the table. + * @target An array of key column names to match on (for SQL Server and Oracle grammars) + * @options Any options to pass to `queryExecute`. Default: {}. + * @toSql If true, returns the raw sql string instead of running the query. Useful for debugging. Default: false. + * + * @return query + */ + public any function insertIgnore( + required any values, + array target = [], + struct options = {}, + boolean toSql = false + ) { + if ( values.isEmpty() ) { + return; + } + + if ( !isArray( values ) ) { + if ( !isStruct( values ) ) { + throw( + type = "InvalidSQLType", + message = "Please pass a struct or an array of structs mapping columns to values" + ); + } + values = [ values ]; + } + + var columns = arguments.values[ 1 ] + .keyArray() + .map( function( column ) { + var formatted = listLast( applyColumnFormatter( column ), "." ); + return { "original": column, "formatted": formatted }; + } ); + columns.sort( function( a, b ) { + return compareNoCase( a.formatted, b.formatted ); + } ); + var newBindings = arguments.values.map( function( value ) { + return columns.map( function( column ) { + return getUtils().extractBinding( + value.keyExists( column.original ) ? value[ column.original ] : javacast( "null", "" ) + ); + } ); + } ); + + newBindings.each( function( bindingsArray ) { + bindingsArray.each( function( binding ) { + if ( getUtils().isNotExpression( binding ) ) { + addBindings( binding, "insert" ); + } else { + addBindings( binding, "insertRaw" ); + } + } ); + } ); + + arguments.target = arrayWrap( arguments.target ).map( function( column ) { + var formatted = listLast( applyColumnFormatter( column ), "." ); + return { "original": column, "formatted": formatted }; + } ); + + var sql = getGrammar().compileInsertIgnore( + this, + columns, + arguments.target, + newBindings + ); + + clearBindings( except = "insert" ); + + if ( toSql ) { + return sql; + } + + return runQuery( sql, arguments.options, "result" ); + } + + public QueryBuilder function returning( required any columns ) { variables.returning = isArray( arguments.columns ) ? arguments.columns : listToArray( arguments.columns ); variables.returning = variables.returning.map( function( column ) { return listLast( applyColumnFormatter( column ), "." ); diff --git a/tests/resources/AbstractQueryBuilderSpec.cfc b/tests/resources/AbstractQueryBuilderSpec.cfc index 5768b9f1..595de845 100644 --- a/tests/resources/AbstractQueryBuilderSpec.cfc +++ b/tests/resources/AbstractQueryBuilderSpec.cfc @@ -2090,6 +2090,18 @@ component extends="testbox.system.BaseSpec" { ); }, insertUsingSelectBuilder() ); } ); + + it( "can insert ignoring conflicts", function() { + testCase( function( builder ) { + return builder + .from( "users" ) + .insertIgnore( + values = [ { "email": "foo", "name": "bar" }, { "email": "baz", "name": "bleh" } ], + target = [ "email" ], + toSql = true + ); + }, insertIgnore() ); + } ); } ); describe( "update statements", function() { diff --git a/tests/specs/Query/MySQLQueryBuilderSpec.cfc b/tests/specs/Query/MySQLQueryBuilderSpec.cfc index 99723732..ef36a336 100644 --- a/tests/specs/Query/MySQLQueryBuilderSpec.cfc +++ b/tests/specs/Query/MySQLQueryBuilderSpec.cfc @@ -658,6 +658,13 @@ component extends="tests.resources.AbstractQueryBuilderSpec" { }; } + function insertIgnore() { + return { + sql: "INSERT IGNORE INTO `users` (`email`, `name`) VALUES (?, ?), (?, ?)", + bindings: [ "foo", "bar", "baz", "bleh" ] + }; + } + function returning() { return { exception: "UnsupportedOperation" }; } diff --git a/tests/specs/Query/OracleQueryBuilderSpec.cfc b/tests/specs/Query/OracleQueryBuilderSpec.cfc index 61776fe6..04c2a633 100644 --- a/tests/specs/Query/OracleQueryBuilderSpec.cfc +++ b/tests/specs/Query/OracleQueryBuilderSpec.cfc @@ -674,6 +674,13 @@ component extends="tests.resources.AbstractQueryBuilderSpec" { }; } + function insertIgnore() { + return { + sql: "MERGE INTO ""USERS"" ""QB_TARGET"" USING (SELECT ?, ? FROM dual UNION ALL SELECT ?, ? FROM dual) ""QB_SRC"" ON ""QB_TARGET"".""EMAIL"" = ""QB_SRC"".""EMAIL"" WHEN NOT MATCHED THEN INSERT (""EMAIL"", ""NAME"") VALUES (""QB_SRC"".""EMAIL"", ""QB_SRC"".""NAME"")", + bindings: [ "foo", "bar", "baz", "bleh" ] + }; + } + function returning() { return { exception: "UnsupportedOperation" }; } diff --git a/tests/specs/Query/PostgresQueryBuilderSpec.cfc b/tests/specs/Query/PostgresQueryBuilderSpec.cfc index 91e967ca..f557b144 100644 --- a/tests/specs/Query/PostgresQueryBuilderSpec.cfc +++ b/tests/specs/Query/PostgresQueryBuilderSpec.cfc @@ -665,6 +665,13 @@ component extends="tests.resources.AbstractQueryBuilderSpec" { }; } + function insertIgnore() { + return { + sql: "INSERT INTO ""users"" (""email"", ""name"") VALUES (?, ?), (?, ?) ON CONFLICT DO NOTHING", + bindings: [ "foo", "bar", "baz", "bleh" ] + }; + } + function returning() { return { sql: "INSERT INTO ""users"" (""email"", ""name"") VALUES (?, ?) RETURNING ""id""", diff --git a/tests/specs/Query/SqlServerQueryBuilderSpec.cfc b/tests/specs/Query/SqlServerQueryBuilderSpec.cfc index 40a11112..99ba6a8a 100644 --- a/tests/specs/Query/SqlServerQueryBuilderSpec.cfc +++ b/tests/specs/Query/SqlServerQueryBuilderSpec.cfc @@ -656,6 +656,13 @@ component extends="tests.resources.AbstractQueryBuilderSpec" { }; } + function insertIgnore() { + return { + sql: "MERGE [users] AS [qb_target] USING (VALUES (?, ?), (?, ?)) AS [qb_src] ([email], [name]) ON [qb_target].[email] = [qb_src].[email] WHEN NOT MATCHED BY TARGET THEN INSERT ([email], [name]) VALUES ([email], [name]);", + bindings: [ "foo", "bar", "baz", "bleh" ] + }; + } + function returning() { return { sql: "INSERT INTO [users] ([email], [name]) OUTPUT INSERTED.[id] VALUES (?, ?)",