Skip to content

Commit

Permalink
feat(QueryBuilder): Add insertIgnore
Browse files Browse the repository at this point in the history
  • Loading branch information
elpete committed Jun 14, 2022
1 parent cc9c106 commit 6238626
Show file tree
Hide file tree
Showing 10 changed files with 191 additions and 2 deletions.
26 changes: 26 additions & 0 deletions models/Grammars/BaseGrammar.cfc
Original file line number Diff line number Diff line change
Expand Up @@ -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.
*
Expand Down
24 changes: 24 additions & 0 deletions models/Grammars/MySQLGrammar.cfc
Original file line number Diff line number Diff line change
Expand Up @@ -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,
Expand Down
3 changes: 2 additions & 1 deletion models/Grammars/OracleGrammar.cfc
Original file line number Diff line number Diff line change
Expand Up @@ -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#)";
}

/**
Expand Down
19 changes: 19 additions & 0 deletions models/Grammars/PostgresGrammar.cfc
Original file line number Diff line number Diff line change
Expand Up @@ -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.
*
Expand Down
81 changes: 80 additions & 1 deletion models/Query/QueryBuilder.cfc
Original file line number Diff line number Diff line change
Expand Up @@ -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 ), "." );
Expand Down
12 changes: 12 additions & 0 deletions tests/resources/AbstractQueryBuilderSpec.cfc
Original file line number Diff line number Diff line change
Expand Up @@ -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() {
Expand Down
7 changes: 7 additions & 0 deletions tests/specs/Query/MySQLQueryBuilderSpec.cfc
Original file line number Diff line number Diff line change
Expand Up @@ -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" };
}
Expand Down
7 changes: 7 additions & 0 deletions tests/specs/Query/OracleQueryBuilderSpec.cfc
Original file line number Diff line number Diff line change
Expand Up @@ -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" };
}
Expand Down
7 changes: 7 additions & 0 deletions tests/specs/Query/PostgresQueryBuilderSpec.cfc
Original file line number Diff line number Diff line change
Expand Up @@ -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""",
Expand Down
7 changes: 7 additions & 0 deletions tests/specs/Query/SqlServerQueryBuilderSpec.cfc
Original file line number Diff line number Diff line change
Expand Up @@ -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 (?, ?)",
Expand Down

0 comments on commit 6238626

Please sign in to comment.