Skip to content

Commit

Permalink
feat(QueryBuilder): Add an upsert method
Browse files Browse the repository at this point in the history
An upsert method allows for updating or inserting records
based on matched keys, usually required to be indexed fields
on the table.
  • Loading branch information
elpete committed Sep 9, 2021
1 parent ab181e2 commit 13debdd
Show file tree
Hide file tree
Showing 10 changed files with 616 additions and 1 deletion.
34 changes: 34 additions & 0 deletions models/Grammars/BaseGrammar.cfc
Expand Up @@ -744,6 +744,40 @@ component displayname="Grammar" accessors="true" singleton {
);
}

public string function compileUpsert(
required QueryBuilder qb,
required array insertColumns,
required array values,
required array updateColumns,
required any updates,
required array target
) {
var insertString = this.compileInsert( arguments.qb, arguments.insertColumns, arguments.values );
var updateString = "";
if ( isArray( arguments.updates ) ) {
updateString = arguments.updateColumns
.map( function( column ) {
return "#wrapValue( column.formatted )# = EXCLUDED.#wrapValue( column.formatted )#";
} )
.toList( ", " );
} else {
updateString = arguments.updateColumns
.map( function( column ) {
var value = updates[ column.original ];
return "#wrapValue( column.formatted )# = #getUtils().isExpression( value ) ? value.getSQL() : "?"#";
} )
.toList( ", " );
}

var constraintString = arguments.target
.map( function( column ) {
return wrapColumn( column.formatted );
} )
.toList( ", " );

return insertString & " ON CONFLICT (#constraintString#) DO UPDATE #updateString#";
}

/**
* Compile a Builder's query into a delete string.
*
Expand Down
26 changes: 26 additions & 0 deletions models/Grammars/MySQLGrammar.cfc
Expand Up @@ -101,6 +101,32 @@ component extends="qb.models.Grammars.BaseGrammar" singleton {
return super.compileInsert( argumentCollection = arguments );
}

public string function compileUpsert(
required QueryBuilder qb,
required array insertColumns,
required array values,
required array updateColumns,
required any updates
) {
var insertString = this.compileInsert( arguments.qb, arguments.insertColumns, arguments.values );
var updateString = "";
if ( isArray( arguments.updates ) ) {
updateString = arguments.updateColumns
.map( function( column ) {
return "#wrapValue( column.formatted )# = VALUES(#wrapValue( column.formatted )#)";
} )
.toList( ", " );
} else {
updateString = arguments.updateColumns
.map( function( column ) {
var value = updates[ column.original ];
return "#wrapValue( column.formatted )# = #getUtils().isExpression( value ) ? value.getSQL() : "?"#";
} )
.toList( ", " );
}
return insertString & " ON DUPLICATE KEY UPDATE #updateString#";
}

function compileDisableForeignKeyConstraints() {
return "SET FOREIGN_KEY_CHECKS=0";
}
Expand Down
60 changes: 60 additions & 0 deletions models/Grammars/OracleGrammar.cfc
Expand Up @@ -135,6 +135,66 @@ component extends="qb.models.Grammars.BaseGrammar" singleton {
return trim( "INSERT#multiple ? " ALL" : ""# #placeholderString##multiple ? " SELECT 1 FROM dual" : ""#" );
}

public string function compileUpsert(
required QueryBuilder qb,
required array insertColumns,
required array values,
required array updateColumns,
required any updates,
required array target
) {
var columnsString = arguments.insertColumns
.map( function( column ) {
return wrapColumn( column.formatted );
} )
.toList( ", " );

var valuesString = arrayToList(
arguments.insertColumns.map( function( column ) {
return wrapColumn( "QB_SRC.#column.formatted#" );
} ),
", "
);

var placeholderString = arguments.values
.map( function( valueArray ) {
return "SELECT " & valueArray
.map( function( item ) {
if ( getUtils().isExpression( item ) ) {
return item.getSQL();
} else {
return "?";
}
} )
.toList( ", " ) & " FROM dual";
} )
.toList( " UNION ALL " );

var constraintString = arguments.target
.map( function( column ) {
return "#wrapColumn( "qb_target.#column.formatted#" )# = #wrapColumn( "qb_src.#column.formatted#" )#";
} )
.toList( " AND " );

var updateList = "";
if ( isArray( arguments.updates ) ) {
updateList = arguments.updates
.map( function( column ) {
return "#wrapColumn( column.formatted )# = #wrapColumn( "qb_src.#column.formatted#" )#";
} )
.toList( ", " );
} else {
updateList = arguments.updateColumns
.map( function( column ) {
var value = updates[ column.original ];
return "#wrapColumn( column.formatted )# = #utils.isExpression( value ) ? value.getSql() : "?"#";
} )
.toList( ", " );
}

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#)";
}

/**
* Since Oracle doesn't know how to do a simple limit of offset without subquerys
* add a subquery around the compiled value for the limit and the offset.
Expand Down
53 changes: 53 additions & 0 deletions models/Grammars/SqlServerGrammar.cfc
Expand Up @@ -250,6 +250,59 @@ component extends="qb.models.Grammars.BaseGrammar" singleton {
);
}

public string function compileUpsert(
required QueryBuilder qb,
required array insertColumns,
required array values,
required array updateColumns,
required any updates,
required array target
) {
var columnsString = arguments.insertColumns
.map( function( column ) {
return wrapColumn( column.formatted );
} )
.toList( ", " );

var placeholderString = arguments.values
.map( function( valueArray ) {
return "(" & valueArray
.map( function( item ) {
if ( getUtils().isExpression( item ) ) {
return item.getSQL();
} else {
return "?";
}
} )
.toList( ", " ) & ")";
} )
.toList( ", " );

var constraintString = arguments.target
.map( function( column ) {
return "#wrapColumn( "qb_target.#column.formatted#" )# = #wrapColumn( "qb_src.#column.formatted#" )#";
} )
.toList( " AND " );

var updateList = "";
if ( isArray( arguments.updates ) ) {
updateList = arguments.updates
.map( function( column ) {
return "#wrapColumn( column.formatted )# = #wrapColumn( "qb_src.#column.formatted#" )#";
} )
.toList( ", " );
} else {
updateList = arguments.updateColumns
.map( function( column ) {
var value = updates[ column.original ];
return "#wrapColumn( column.formatted )# = #utils.isExpression( value ) ? value.getSql() : "?"#";
} )
.toList( ", " );
}

return "MERGE #wrapTable( arguments.qb.getFrom() )# AS [qb_target] USING (VALUES #placeholderString#) AS [qb_src] (#columnsString#) ON #constraintString# WHEN MATCHED THEN UPDATE SET #updateList# WHEN NOT MATCHED BY TARGET THEN INSERT (#columnsString#) VALUES (#columnsString#)";
}

function generateType( column, blueprint ) {
if ( column.getComputedType() != "none" ) {
return "";
Expand Down
106 changes: 106 additions & 0 deletions models/Query/QueryBuilder.cfc
Expand Up @@ -2553,6 +2553,112 @@ component displayname="QueryBuilder" accessors="true" {
return this.insert( argumentCollection = arguments );
}


public any function upsert(
required any values,
required any target,
any update,
struct options = {},
boolean toSql = false
) {
if ( arguments.values.isEmpty() ) {
return;
}

if ( !isArray( arguments.values ) ) {
if ( !isStruct( arguments.values ) ) {
throw(
type = "InvalidSQLType",
message = "Please pass a struct or an array of structs mapping columns to values"
);
}
arguments.values = arrayWrap( arguments.values );
}

if ( !isNull( arguments.update ) && arguments.update.isEmpty() ) {
return this.insert( values = arguments.values, options = arguments.options, toSql = arguments.toSql );
}

arguments.target = arrayWrap( arguments.target ).map( function( column ) {
var formatted = listLast( applyColumnFormatter( column ), "." );
return { "original": column, "formatted": formatted };
} );

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 updateArray = [];
if ( isNull( arguments.update ) ) {
arguments.update = columns;
} else {
if ( isArray( arguments.update ) ) {
arguments.update = arguments.update.map( function( column ) {
var formatted = listLast( applyColumnFormatter( column ), "." );
return { "original": column, "formatted": formatted };
} );
}
}

if ( isArray( arguments.update ) ) {
updateArray = arguments.update;
} else {
updateArray = arguments.update
.keyArray()
.map( function( column ) {
var formatted = listLast( applyColumnFormatter( column ), "." );
return { original: column, formatted: formatted };
} );
}

updateArray.sort( function( a, b ) {
return compareNoCase( a.formatted, b.formatted );
} );

var newInsertBindings = arguments.values.map( function( value ) {
return columns.map( function( column ) {
return getUtils().extractBinding(
value.keyExists( column.original ) ? value[ column.original ] : javacast( "null", "" )
);
} );
} );

newInsertBindings.each( function( bindingsArray ) {
bindingsArray.each( function( binding ) {
if ( getUtils().isNotExpression( binding ) ) {
addBindings( binding, "insert" );
} else {
addBindings( binding, "insertRaw" );
}
} );
} );

var sql = getGrammar().compileUpsert(
this,
columns,
newInsertBindings,
updateArray,
arguments.update,
arguments.target
);

clearBindings( except = [ "insert", "update" ] );

if ( toSql ) {
return sql;
}

return runQuery( sql, arguments.options, "result" );
}


/**
* Deletes a record set.
* This call must come after setting the query's table using `from` or `table`.
Expand Down

0 comments on commit 13debdd

Please sign in to comment.