Skip to content

Commit

Permalink
feat(Locks): Add locking helpers to qb
Browse files Browse the repository at this point in the history
Select queries can now add locking text based on the following methods:

1. noLock() -> Adds a NO LOCK hint in appropriate grammars.
2. sharedLock() -> Adds a lock to prevent updates but allow selects for the selected rows.
3. lockForUpdate() -> Adds a lock for updating the selected rows.
4. lock( required string value ) -> Adds a custom lock text.
  • Loading branch information
elpete committed Mar 23, 2021
1 parent 6c94e46 commit b986211
Show file tree
Hide file tree
Showing 10 changed files with 267 additions and 2 deletions.
26 changes: 25 additions & 1 deletion models/Grammars/BaseGrammar.cfc
Expand Up @@ -47,7 +47,8 @@ component displayname="Grammar" accessors="true" singleton {
"unions",
"orders",
"limitValue",
"offsetValue"
"offsetValue",
"lockType"
];

/**
Expand Down Expand Up @@ -658,6 +659,29 @@ component displayname="Grammar" accessors="true" singleton {
return "OFFSET #offsetValue#";
}

/**
* Compiles the lock portion of a sql statement.
*
* @query The Builder instance.
* @lockType The lock type to compile.
*
* @return string
*/
private string function compileLockType( required query, required string lockType ) {
switch ( arguments.lockType ) {
case "shared":
return "LOCK IN SHARE MODE";
case "update":
return "FOR UPDATE";
case "custom":
return arguments.query.getLockValue();
case "none":
case "nolock":
default:
return "";
}
}

/**
* Compile a Builder's query into an insert string.
*
Expand Down
37 changes: 36 additions & 1 deletion models/Grammars/OracleGrammar.cfc
Expand Up @@ -42,8 +42,43 @@ component extends="qb.models.Grammars.BaseGrammar" singleton {
*/
public string function compileSelect( required QueryBuilder query ) {
var sql = super.compileSelect( argumentCollection = arguments );
sql = compileOracleLimitAndOffset( query, sql );
return compileOracleLockType( query, sql );
}

/**
* Compiles the lock portion of a sql statement.
*
* @query The Builder instance.
* @lockType The lock type to compile.
*
* @return string
*/
private string function compileLockType( required query, required string lockType ) {
return ""; // Oracle grammar adds it as an additional statement before the select statement.
}

return compileOracleLimitAndOffset( query, sql );
/**
* Compiles the lock portion of a sql statement.
*
* @query The Builder instance.
* @lockType The lock type to compile.
*
* @return string
*/
private string function compileOracleLockType( required query, required string sql ) {
switch ( arguments.query.getLockType() ) {
case "shared":
return "LOCK TABLE #wrapTable( arguments.query.getFrom() )# IN SHARE MODE NOWAIT; #arguments.sql#";
case "update":
return "LOCK TABLE #wrapTable( arguments.query.getFrom() )# IN ROW EXCLUSIVE MODE NOWAIT; #arguments.sql#";
case "custom":
return "LOCK TABLE #wrapTable( arguments.query.getFrom() )# IN #arguments.query.getLockValue()# MODE NOWAIT; #arguments.sql#";
case "none":
case "nolock":
default:
return arguments.sql;
}
}

/**
Expand Down
23 changes: 23 additions & 0 deletions models/Grammars/PostgresGrammar.cfc
@@ -1,5 +1,28 @@
component extends="qb.models.Grammars.BaseGrammar" singleton {

/**
* Compiles the lock portion of a sql statement.
*
* @query The Builder instance.
* @lockType The lock type to compile.
*
* @return string
*/
private string function compileLockType( required query, required string lockType ) {
switch ( arguments.lockType ) {
case "shared":
return "FOR SHARE";
case "update":
return "FOR UPDATE";
case "custom":
return arguments.query.getLockValue();
case "none":
case "nolock":
default:
return "";
}
}

/**
* Compile a Builder's query into an insert string.
*
Expand Down
25 changes: 25 additions & 0 deletions models/Grammars/SqlServerGrammar.cfc
Expand Up @@ -13,6 +13,7 @@ component extends="qb.models.Grammars.BaseGrammar" singleton {
"aggregate",
"columns",
"from",
"lockType",
"joins",
"wheres",
"groups",
Expand Down Expand Up @@ -101,6 +102,30 @@ component extends="qb.models.Grammars.BaseGrammar" singleton {
return select & columns.map( wrapColumn ).toList( ", " );
}

/**
* Compiles the lock portion of a sql statement.
*
* @query The Builder instance.
* @lockType The lock type to compile.
*
* @return string
*/
private string function compileLockType( required query, required string lockType ) {
switch ( arguments.lockType ) {
case "nolock":
return "WITH (NOLOCK)";
case "shared":
return "WITH (ROWLOCK,HOLDLOCK)";
case "update":
return "WITH (ROWLOCK,UPDLOCK,HOLDLOCK)";
case "custom":
return arguments.query.getLockValue();
case "none":
default:
return "";
}
}

/**
* Compiles the order by portion of a sql statement.
*
Expand Down
47 changes: 47 additions & 0 deletions models/Query/QueryBuilder.cfc
Expand Up @@ -95,6 +95,17 @@ component displayname="QueryBuilder" accessors="true" {
*/
property name="from" type="string";

/**
* The type of lock for the table. Default: `none`
* Expected values are `none`, `nolock`, `shared`, `update`, and `custom`.
*/
property name="lockType" type="string";

/**
* The value for a custom lock.
*/
property name="lockValue" type="string";

/**
* An array of JOIN statements.
* @default []
Expand Down Expand Up @@ -294,6 +305,8 @@ component displayname="QueryBuilder" accessors="true" {
variables.unions = [];
variables.returning = [];
variables.updates = {};
variables.lockType = "none";
variables.lockValue = "";
}

/**********************************************************************************************\
Expand Down Expand Up @@ -531,6 +544,40 @@ component displayname="QueryBuilder" accessors="true" {
return this.fromRaw( getGrammar().wrapTable( "(#arguments.input.toSQL()#) AS #arguments.alias#" ) );
}

/*******************************************************************************\
| LOCK functions |
\*******************************************************************************/

public QueryBuilder function lock( required string value ) {
variables.lockType = "custom";
variables.lockValue = arguments.value;
return this;
}

public QueryBuilder function noLock() {
variables.lockType = "nolock";
variables.lockValue = "";
return this;
}

public QueryBuilder function sharedLock() {
variables.lockType = "shared";
variables.lockValue = "";
return this;
}

public QueryBuilder function lockForUpdate() {
variables.lockType = "update";
variables.lockValue = "";
return this;
}

public QueryBuilder function clearLock() {
variables.lockType = "none";
variables.lockValue = "";
return this;
}

/*******************************************************************************\
| JOIN clause functions |
\*******************************************************************************/
Expand Down
38 changes: 38 additions & 0 deletions tests/resources/AbstractQueryBuilderSpec.cfc
Expand Up @@ -238,6 +238,44 @@ component extends="testbox.system.BaseSpec" {
} );
} );

describe( "locking", function() {
it( "can set no lock", function() {
testCase( function( builder ) {
builder
.from( "users" )
.where( "id", 1 )
.noLock();
}, noLock() );
} );

it( "can set a shared lock", function() {
testCase( function( builder ) {
builder
.from( "users" )
.where( "id", 1 )
.sharedLock();
}, sharedLock() );
} );

it( "can lock for update", function() {
testCase( function( builder ) {
builder
.from( "users" )
.where( "id", 1 )
.lockForUpdate();
}, lockForUpdate() );
} );

it( "can pass an arbitrary string to lock", function() {
testCase( function( builder ) {
builder
.from( "users" )
.where( "id", 1 )
.lock( "foobar" );
}, lockArbitraryString() );
} );
} );

describe( "using table prefixes", function() {
it( "can perform a basic select with a table prefix", function() {
testCase( function( builder ) {
Expand Down
16 changes: 16 additions & 0 deletions tests/specs/Query/MySQLQueryBuilderSpec.cfc
Expand Up @@ -94,6 +94,22 @@ component extends="tests.resources.AbstractQueryBuilderSpec" {
return { sql: "SELECT * FROM (SELECT `id`, `name` FROM `users` WHERE `age` >= ?) AS `u`", bindings: [ 21 ] };
}

function noLock() {
return { sql: "SELECT * FROM `users` WHERE `id` = ?", bindings: [ 1 ] };
}

function sharedLock() {
return { sql: "SELECT * FROM `users` WHERE `id` = ? LOCK IN SHARE MODE", bindings: [ 1 ] };
}

function lockForUpdate() {
return { sql: "SELECT * FROM `users` WHERE `id` = ? FOR UPDATE", bindings: [ 1 ] };
}

function lockArbitraryString() {
return { sql: "SELECT * FROM `users` WHERE `id` = ? foobar", bindings: [ 1 ] };
}

function table() {
return "SELECT * FROM `users`";
}
Expand Down
25 changes: 25 additions & 0 deletions tests/specs/Query/OracleQueryBuilderSpec.cfc
Expand Up @@ -97,6 +97,31 @@ component extends="tests.resources.AbstractQueryBuilderSpec" {
};
}

function noLock() {
return { "sql": "SELECT * FROM ""USERS"" WHERE ""ID"" = ?", "bindings": [ 1 ] };
}

function sharedLock() {
return {
"sql": "LOCK TABLE ""USERS"" IN SHARE MODE NOWAIT; SELECT * FROM ""USERS"" WHERE ""ID"" = ?",
"bindings": [ 1 ]
};
}

function lockForUpdate() {
return {
"sql": "LOCK TABLE ""USERS"" IN ROW EXCLUSIVE MODE NOWAIT; SELECT * FROM ""USERS"" WHERE ""ID"" = ?",
"bindings": [ 1 ]
};
}

function lockArbitraryString() {
return {
"sql": "LOCK TABLE ""USERS"" IN foobar MODE NOWAIT; SELECT * FROM ""USERS"" WHERE ""ID"" = ?",
"bindings": [ 1 ]
};
}

function table() {
return "SELECT * FROM ""USERS""";
}
Expand Down
16 changes: 16 additions & 0 deletions tests/specs/Query/PostgresQueryBuilderSpec.cfc
Expand Up @@ -97,6 +97,22 @@ component extends="tests.resources.AbstractQueryBuilderSpec" {
};
}

function noLock() {
return { "sql": "SELECT * FROM ""users"" WHERE ""id"" = ?", "bindings": [ 1 ] };
}

function sharedLock() {
return { "sql": "SELECT * FROM ""users"" WHERE ""id"" = ? FOR SHARE", "bindings": [ 1 ] };
}

function lockForUpdate() {
return { "sql": "SELECT * FROM ""users"" WHERE ""id"" = ? FOR UPDATE", "bindings": [ 1 ] };
}

function lockArbitraryString() {
return { "sql": "SELECT * FROM ""users"" WHERE ""id"" = ? foobar", "bindings": [ 1 ] };
}

function table() {
return "SELECT * FROM ""users""";
}
Expand Down
16 changes: 16 additions & 0 deletions tests/specs/Query/SqlServerQueryBuilderSpec.cfc
Expand Up @@ -94,6 +94,22 @@ component extends="tests.resources.AbstractQueryBuilderSpec" {
return { sql: "SELECT * FROM (SELECT [id], [name] FROM [users] WHERE [age] >= ?) AS [u]", bindings: [ 21 ] };
}

function noLock() {
return { "sql": "SELECT * FROM [users] WITH (NOLOCK) WHERE [id] = ?", "bindings": [ 1 ] };
}

function sharedLock() {
return { "sql": "SELECT * FROM [users] WITH (ROWLOCK,HOLDLOCK) WHERE [id] = ?", "bindings": [ 1 ] };
}

function lockForUpdate() {
return { "sql": "SELECT * FROM [users] WITH (ROWLOCK,UPDLOCK,HOLDLOCK) WHERE [id] = ?", "bindings": [ 1 ] };
}

function lockArbitraryString() {
return { "sql": "SELECT * FROM [users] foobar WHERE [id] = ?", "bindings": [ 1 ] };
}

function table() {
return "SELECT * FROM [users]";
}
Expand Down

0 comments on commit b986211

Please sign in to comment.