From b9862110ba5bda21f9883eff28c3253ea11fefab Mon Sep 17 00:00:00 2001 From: Eric Peterson Date: Mon, 22 Mar 2021 22:13:14 -0600 Subject: [PATCH] feat(Locks): Add locking helpers to qb 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. --- models/Grammars/BaseGrammar.cfc | 26 +++++++++- models/Grammars/OracleGrammar.cfc | 37 ++++++++++++++- models/Grammars/PostgresGrammar.cfc | 23 +++++++++ models/Grammars/SqlServerGrammar.cfc | 25 ++++++++++ models/Query/QueryBuilder.cfc | 47 +++++++++++++++++++ tests/resources/AbstractQueryBuilderSpec.cfc | 38 +++++++++++++++ tests/specs/Query/MySQLQueryBuilderSpec.cfc | 16 +++++++ tests/specs/Query/OracleQueryBuilderSpec.cfc | 25 ++++++++++ .../specs/Query/PostgresQueryBuilderSpec.cfc | 16 +++++++ .../specs/Query/SqlServerQueryBuilderSpec.cfc | 16 +++++++ 10 files changed, 267 insertions(+), 2 deletions(-) diff --git a/models/Grammars/BaseGrammar.cfc b/models/Grammars/BaseGrammar.cfc index 8c3d7428..92b2941c 100644 --- a/models/Grammars/BaseGrammar.cfc +++ b/models/Grammars/BaseGrammar.cfc @@ -47,7 +47,8 @@ component displayname="Grammar" accessors="true" singleton { "unions", "orders", "limitValue", - "offsetValue" + "offsetValue", + "lockType" ]; /** @@ -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. * diff --git a/models/Grammars/OracleGrammar.cfc b/models/Grammars/OracleGrammar.cfc index c978afce..8106fcb8 100644 --- a/models/Grammars/OracleGrammar.cfc +++ b/models/Grammars/OracleGrammar.cfc @@ -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; + } } /** diff --git a/models/Grammars/PostgresGrammar.cfc b/models/Grammars/PostgresGrammar.cfc index 2da2a151..dffdd6c2 100644 --- a/models/Grammars/PostgresGrammar.cfc +++ b/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. * diff --git a/models/Grammars/SqlServerGrammar.cfc b/models/Grammars/SqlServerGrammar.cfc index 05341754..e829cb9c 100644 --- a/models/Grammars/SqlServerGrammar.cfc +++ b/models/Grammars/SqlServerGrammar.cfc @@ -13,6 +13,7 @@ component extends="qb.models.Grammars.BaseGrammar" singleton { "aggregate", "columns", "from", + "lockType", "joins", "wheres", "groups", @@ -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. * diff --git a/models/Query/QueryBuilder.cfc b/models/Query/QueryBuilder.cfc index 40236020..a46d0539 100644 --- a/models/Query/QueryBuilder.cfc +++ b/models/Query/QueryBuilder.cfc @@ -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 [] @@ -294,6 +305,8 @@ component displayname="QueryBuilder" accessors="true" { variables.unions = []; variables.returning = []; variables.updates = {}; + variables.lockType = "none"; + variables.lockValue = ""; } /**********************************************************************************************\ @@ -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 | \*******************************************************************************/ diff --git a/tests/resources/AbstractQueryBuilderSpec.cfc b/tests/resources/AbstractQueryBuilderSpec.cfc index 1121f896..88a078ee 100644 --- a/tests/resources/AbstractQueryBuilderSpec.cfc +++ b/tests/resources/AbstractQueryBuilderSpec.cfc @@ -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 ) { diff --git a/tests/specs/Query/MySQLQueryBuilderSpec.cfc b/tests/specs/Query/MySQLQueryBuilderSpec.cfc index b7e22aa1..c1440ef4 100644 --- a/tests/specs/Query/MySQLQueryBuilderSpec.cfc +++ b/tests/specs/Query/MySQLQueryBuilderSpec.cfc @@ -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`"; } diff --git a/tests/specs/Query/OracleQueryBuilderSpec.cfc b/tests/specs/Query/OracleQueryBuilderSpec.cfc index 7a5dc9eb..63efbdd7 100644 --- a/tests/specs/Query/OracleQueryBuilderSpec.cfc +++ b/tests/specs/Query/OracleQueryBuilderSpec.cfc @@ -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"""; } diff --git a/tests/specs/Query/PostgresQueryBuilderSpec.cfc b/tests/specs/Query/PostgresQueryBuilderSpec.cfc index b0292fe5..7956145c 100644 --- a/tests/specs/Query/PostgresQueryBuilderSpec.cfc +++ b/tests/specs/Query/PostgresQueryBuilderSpec.cfc @@ -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"""; } diff --git a/tests/specs/Query/SqlServerQueryBuilderSpec.cfc b/tests/specs/Query/SqlServerQueryBuilderSpec.cfc index 9edec5d7..6fa47c9a 100644 --- a/tests/specs/Query/SqlServerQueryBuilderSpec.cfc +++ b/tests/specs/Query/SqlServerQueryBuilderSpec.cfc @@ -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]"; }