Skip to content
Projects
Groups
Snippets
Help
This project
Loading...
Sign in / Register
Toggle navigation
Y
yii2
Project
Overview
Details
Activity
Cycle Analytics
Repository
Repository
Files
Commits
Branches
Tags
Contributors
Graph
Compare
Charts
Issues
0
Issues
0
List
Board
Labels
Milestones
Merge Requests
0
Merge Requests
0
CI / CD
CI / CD
Pipelines
Jobs
Schedules
Charts
Wiki
Wiki
Snippets
Snippets
Members
Members
Collapse sidebar
Close sidebar
Activity
Graph
Charts
Create a new issue
Jobs
Commits
Issue Boards
Open sidebar
PSDI Army
yii2
Commits
6e0ee4ed
Commit
6e0ee4ed
authored
Jun 24, 2014
by
Carsten Brandt
Browse files
Options
Browse Files
Download
Plain Diff
Merge pull request #4026 from yiisoft/transaction-isolation
Added support for transaction isolation levels
parents
716e683a
6ad24418
Show whitespace changes
Inline
Side-by-side
Showing
10 changed files
with
266 additions
and
7 deletions
+266
-7
db-dao.md
docs/guide/db-dao.md
+54
-3
CHANGELOG.md
framework/CHANGELOG.md
+1
-0
Connection.php
framework/db/Connection.php
+4
-2
Schema.php
framework/db/Schema.php
+13
-0
Transaction.php
framework/db/Transaction.php
+62
-2
Schema.php
framework/db/cubrid/Schema.php
+25
-0
Schema.php
framework/db/sqlite/Schema.php
+25
-0
ConnectionTest.php
tests/unit/framework/db/ConnectionTest.php
+44
-0
PostgreSQLConnectionTest.php
tests/unit/framework/db/pgsql/PostgreSQLConnectionTest.php
+26
-0
SqliteConnectionTest.php
tests/unit/framework/db/sqlite/SqliteConnectionTest.php
+12
-0
No files found.
docs/guide/db-dao.md
View file @
6e0ee4ed
...
...
@@ -249,7 +249,11 @@ $command->execute();
Transactions
------------
You can perform transactional SQL queries like the following:
When running multiple related queries in a sequence you may need to wrap them in a transaction to
ensure you data is consistent. Yii provides a simple interface to work with transactions in simple
cases but also for advanced usage when you need to define isolation levels.
The following code shows a simple pattern that all code that uses transactional queries should follow:
```
php
$transaction = $connection->beginTransaction();
...
...
@@ -258,12 +262,22 @@ try {
$connection->createCommand($sql2)->execute();
// ... executing other SQL statements ...
$transaction->commit();
} catch(Exception $e) {
} catch(
\
E
xception $e) {
$transaction->rollBack();
throw $e;
}
```
You can also nest multiple transactions, if needed:
The first line starts a new transaction using the [[yii\db\Connection::beginTransaction()|beginTransaction()]]-method of the database connection
object. The transaction itself is represented by a [[yii\db\Transaction]] object stored in `$transaction`.
We wrap the execution of all queries in a try-catch-block to be able to handle errors.
We call [[yii\db\Transaction::commit()|commit()]] on success to commit the transaction and
[[yii\db\Transaction::rollBack()|rollBack()]] in case of an error. This will revert the effect of all queries
that have been executed inside of the transaction.
`throw $e` is used to re-throw the exception in case we can not handle the error ourselfs and deligate it
to some other code or the yii errorhandler.
It is also possible to nest multiple transactions, if needed:
```
php
// outer transaction
...
...
@@ -286,6 +300,43 @@ try {
}
```
Note that your DBMS should have support for Savepoints for this to work as expected.
The above code will work for any DBMS but transactional safety is only guaranteed if
the underlying DBMS supports it.
Yii also supports setting [isolation levels] for your transactions.
When beginning a transaction it will run in the default isolation level set by you database system.
You can specifying an isolation level explicitly when starting a transaction:
```
php
$transaction = $connection->beginTransaction(
\y
ii
\d
b
\T
ransaction::REPEATABLE_READ);
```
Yii provides four constants for the most common isolation levels:
- [[\yii\db\Transaction::READ_UNCOMMITTED]] - the weakest level, Dirty reads, Non-repeatable reads and Phantoms may occur.
- [[\yii\db\Transaction::READ_COMMITTED]] - avoid Dirty reads.
- [[\yii\db\Transaction::REPEATABLE_READ]] - avoid Dirty reads and Non-repeatable reads.
- [[\yii\db\Transaction::SERIALIZABLE]] - the strongest level, avoids all of the above named problems.
You may use the constants named above but you can also use a string that represents a valid syntax that can be
used in your DBMS following `SET TRANSACTION ISOLATION LEVEL`. For postgres this could be for example
`SERIALIZABLE READ ONLY DEFERRABLE`.
Note that some DBMS allow setting of the isolation level only for the whole connection so subsequent transactions
may get the same isolation level even if you did not specify any. When using this feature
you may need to set the isolation level for all transactions explicitly to avoid conflicting settings.
At the time of this writing affected DBMS are MSSQL and SQLite.
> Note: SQLite only supports two isolation levels, so you can only use `READ UNCOMMITTED` and `SERIALIZABLE`.
Usage of other levels will result in an exception to be thrown.
> Note: PostgreSQL does not allow settin the isolation level before the transaction starts so you can not
specify the isolation level directly when starting the transaction.
You have to call [[yii\db\Transaction::setIsolationLevel()]] in this case after the transaction has started.
[isolation levels]: http://en.wikipedia.org/wiki/Isolation_%28database_systems%29#Isolation_levels
Working with database schema
----------------------------
...
...
framework/CHANGELOG.md
View file @
6e0ee4ed
...
...
@@ -68,6 +68,7 @@ Yii Framework 2 Change Log
-
Enh #3132:
`yii\rbac\PhpManager`
now supports more compact data file format (qiangxue)
-
Enh #3154: Added validation error display for
`GridView`
filters (ivan-kolmychek)
-
Enh #3196: Masked input upgraded to use jquery.inputmask plugin with more features. (kartik-v)
-
Enh #3220: Added support for setting transation isolation levels (cebe)
-
Enh #3222: Added
`useTablePrefix`
option to the model generator for Gii (horizons2)
-
Enh #3230: Added
`yii\filters\AccessControl::user`
to support access control with different actors (qiangxue)
-
Enh #3232: Added
`export()`
and
`exportAsString()`
methods to
`yii\helpers\BaseVarDumper`
(klimov-paul)
...
...
framework/db/Connection.php
View file @
6e0ee4ed
...
...
@@ -410,16 +410,18 @@ class Connection extends Component
/**
* Starts a transaction.
* @param string|null $isolationLevel The isolation level to use for this transaction.
* See [[Transaction::begin()]] for details.
* @return Transaction the transaction initiated
*/
public
function
beginTransaction
()
public
function
beginTransaction
(
$isolationLevel
=
null
)
{
$this
->
open
();
if
((
$transaction
=
$this
->
getTransaction
())
===
null
)
{
$transaction
=
$this
->
_transaction
=
new
Transaction
([
'db'
=>
$this
]);
}
$transaction
->
begin
();
$transaction
->
begin
(
$isolationLevel
);
return
$transaction
;
}
...
...
framework/db/Schema.php
View file @
6e0ee4ed
...
...
@@ -340,6 +340,19 @@ abstract class Schema extends Object
}
/**
* Sets the isolation level of the current transaction.
* @param string $level The transaction isolation level to use for this transaction.
* This can be one of [[Transaction::READ_UNCOMMITTED]], [[Transaction::READ_COMMITTED]], [[Transaction::REPEATABLE_READ]]
* and [[Transaction::SERIALIZABLE]] but also a string containing DBMS specific syntax to be used
* after `SET TRANSACTION ISOLATION LEVEL`.
* @see http://en.wikipedia.org/wiki/Isolation_%28database_systems%29#Isolation_levels
*/
public
function
setTransactionIsolationLevel
(
$level
)
{
$this
->
db
->
createCommand
(
"SET TRANSACTION ISOLATION LEVEL
$level
;"
)
->
execute
();
}
/**
* Quotes a string value for use in a query.
* Note that if the parameter is not a string, it will be returned without change.
* @param string $str string to be quoted
...
...
framework/db/Transaction.php
View file @
6e0ee4ed
...
...
@@ -39,6 +39,27 @@ use yii\base\InvalidConfigException;
class
Transaction
extends
\yii\base\Object
{
/**
* A constant representing the transaction isolation level `READ UNCOMMITTED`.
* @see http://en.wikipedia.org/wiki/Isolation_%28database_systems%29#Isolation_levels
*/
const
READ_UNCOMMITTED
=
'READ UNCOMMITTED'
;
/**
* A constant representing the transaction isolation level `READ COMMITTED`.
* @see http://en.wikipedia.org/wiki/Isolation_%28database_systems%29#Isolation_levels
*/
const
READ_COMMITTED
=
'READ COMMITTED'
;
/**
* A constant representing the transaction isolation level `REPEATABLE READ`.
* @see http://en.wikipedia.org/wiki/Isolation_%28database_systems%29#Isolation_levels
*/
const
REPEATABLE_READ
=
'REPEATABLE READ'
;
/**
* A constant representing the transaction isolation level `SERIALIZABLE`.
* @see http://en.wikipedia.org/wiki/Isolation_%28database_systems%29#Isolation_levels
*/
const
SERIALIZABLE
=
'SERIALIZABLE'
;
/**
* @var Connection the database connection that this transaction is associated with.
*/
public
$db
;
...
...
@@ -47,6 +68,7 @@ class Transaction extends \yii\base\Object
*/
private
$_level
=
0
;
/**
* Returns a value indicating whether this transaction is active.
* @return boolean whether this transaction is active. Only an active transaction
...
...
@@ -59,9 +81,23 @@ class Transaction extends \yii\base\Object
/**
* Begins a transaction.
* @param string|null $isolationLevel The [isolation level][] to use for this transaction.
* This can be one of [[READ_UNCOMMITTED]], [[READ_COMMITTED]], [[REPEATABLE_READ]] and [[SERIALIZABLE]] but
* also a string containing DBMS specific syntax to be used after `SET TRANSACTION ISOLATION LEVEL`.
* If not specified (`null`) the isolation level will not be set explicitly and the DBMS default will be used.
*
* > Note: This setting does not work for PostgreSQL, where setting the isolation level before the transaction
* has no effect. You have to call [[setIsolationLevel()]] in this case after the transaction has started.
*
* > Note: Some DBMS allow setting of the isolation level only for the whole connection so subsequent transactions
* may get the same isolation level even if you did not specify any. When using this feature
* you may need to set the isolation level for all transactions explicitly to avoid conflicting settings.
* At the time of this writing affected DBMS are MSSQL and SQLite.
*
* [isolation level]: http://en.wikipedia.org/wiki/Isolation_%28database_systems%29#Isolation_levels
* @throws InvalidConfigException if [[db]] is `null`.
*/
public
function
begin
()
public
function
begin
(
$isolationLevel
=
null
)
{
if
(
$this
->
db
===
null
)
{
throw
new
InvalidConfigException
(
'Transaction::db must be set.'
);
...
...
@@ -69,7 +105,10 @@ class Transaction extends \yii\base\Object
$this
->
db
->
open
();
if
(
$this
->
_level
==
0
)
{
Yii
::
trace
(
'Begin transaction'
,
__METHOD__
);
if
(
$isolationLevel
!==
null
)
{
$this
->
db
->
getSchema
()
->
setTransactionIsolationLevel
(
$isolationLevel
);
}
Yii
::
trace
(
'Begin transaction'
.
(
$isolationLevel
?
' with isolation level '
.
$isolationLevel
:
''
),
__METHOD__
);
$this
->
db
->
pdo
->
beginTransaction
();
$this
->
_level
=
1
;
...
...
@@ -141,4 +180,25 @@ class Transaction extends \yii\base\Object
throw
new
Exception
(
'Roll back failed: nested transaction not supported.'
);
}
}
/**
* Sets the transaction isolation level for this transaction.
*
* This method can be used to set the isolation level while the transaction is already active.
* However this is not supported by all DBMS so you might rather specify the isolation level directly
* when calling [[begin()]].
* @param string $level The transaction isolation level to use for this transaction.
* This can be one of [[READ_UNCOMMITTED]], [[READ_COMMITTED]], [[REPEATABLE_READ]] and [[SERIALIZABLE]] but
* also a string containing DBMS specific syntax to be used after `SET TRANSACTION ISOLATION LEVEL`.
* @throws Exception if the transaction is not active
* @see http://en.wikipedia.org/wiki/Isolation_%28database_systems%29#Isolation_levels
*/
public
function
setIsolationLevel
(
$level
)
{
if
(
!
$this
->
getIsActive
())
{
throw
new
Exception
(
'Failed to set isolation level: transaction was inactive.'
);
}
Yii
::
trace
(
'Setting transaction isolation level to '
.
$level
,
__METHOD__
);
$this
->
db
->
getSchema
()
->
setTransactionIsolationLevel
(
$level
);
}
}
framework/db/cubrid/Schema.php
View file @
6e0ee4ed
...
...
@@ -10,6 +10,7 @@ namespace yii\db\cubrid;
use
yii\db\Expression
;
use
yii\db\TableSchema
;
use
yii\db\ColumnSchema
;
use
yii\db\Transaction
;
/**
* Schema is the class for retrieving metadata from a CUBRID database (version 9.1.x and higher).
...
...
@@ -284,4 +285,28 @@ class Schema extends \yii\db\Schema
return
isset
(
$typeMap
[
$type
])
?
$typeMap
[
$type
]
:
\PDO
::
PARAM_STR
;
}
/**
* @inheritdoc
* @see http://www.cubrid.org/manual/91/en/sql/transaction.html#database-concurrency
*/
public
function
setTransactionIsolationLevel
(
$level
)
{
// translate SQL92 levels to CUBRID levels:
switch
(
$level
)
{
case
Transaction
::
SERIALIZABLE
:
$level
=
'6'
;
// SERIALIZABLE
break
;
case
Transaction
::
REPEATABLE_READ
:
$level
=
'5'
;
// REPEATABLE READ CLASS with REPEATABLE READ INSTANCES
break
;
case
Transaction
::
READ_COMMITTED
:
$level
=
'4'
;
// REPEATABLE READ CLASS with READ COMMITTED INSTANCES
break
;
case
Transaction
::
READ_UNCOMMITTED
:
$level
=
'3'
;
// REPEATABLE READ CLASS with READ UNCOMMITTED INSTANCES
break
;
}
parent
::
setTransactionIsolationLevel
(
$level
);
}
}
framework/db/sqlite/Schema.php
View file @
6e0ee4ed
...
...
@@ -7,8 +7,10 @@
namespace
yii\db\sqlite
;
use
yii\base\NotSupportedException
;
use
yii\db\TableSchema
;
use
yii\db\ColumnSchema
;
use
yii\db\Transaction
;
/**
* Schema is the class for retrieving metadata from a SQLite (2/3) database.
...
...
@@ -249,4 +251,27 @@ class Schema extends \yii\db\Schema
return
$column
;
}
/**
* Sets the isolation level of the current transaction.
* @param string $level The transaction isolation level to use for this transaction.
* This can be either [[Transaction::READ_UNCOMMITTED]] or [[Transaction::SERIALIZABLE]].
* @throws \yii\base\NotSupportedException when unsupported isolation levels are used.
* SQLite only supports SERIALIZABLE and READ UNCOMMITTED.
* @see http://www.sqlite.org/pragma.html#pragma_read_uncommitted
*/
public
function
setTransactionIsolationLevel
(
$level
)
{
switch
(
$level
)
{
case
Transaction
::
SERIALIZABLE
:
$this
->
db
->
createCommand
(
"PRAGMA read_uncommitted = False;"
)
->
execute
();
break
;
case
Transaction
::
READ_UNCOMMITTED
:
$this
->
db
->
createCommand
(
"PRAGMA read_uncommitted = True;"
)
->
execute
();
break
;
default
:
throw
new
NotSupportedException
(
get_class
(
$this
)
.
' only supports transaction isolation levels READ UNCOMMITTED and SERIALIZABLE.'
);
}
}
}
tests/unit/framework/db/ConnectionTest.php
View file @
6e0ee4ed
...
...
@@ -3,6 +3,7 @@
namespace
yiiunit\framework\db
;
use
yii\db\Connection
;
use
yii\db\Transaction
;
/**
* @group db
...
...
@@ -77,4 +78,47 @@ class ConnectionTest extends DatabaseTestCase
$this
->
assertEquals
(
'{{column}}'
,
$connection
->
quoteColumnName
(
'{{column}}'
));
$this
->
assertEquals
(
'(column)'
,
$connection
->
quoteColumnName
(
'(column)'
));
}
public
function
testTransaction
()
{
$connection
=
$this
->
getConnection
(
false
);
$this
->
assertNull
(
$connection
->
transaction
);
$transaction
=
$connection
->
beginTransaction
();
$this
->
assertNotNull
(
$connection
->
transaction
);
$this
->
assertTrue
(
$transaction
->
isActive
);
$connection
->
createCommand
()
->
insert
(
'profile'
,
[
'description'
=>
'test transaction'
])
->
execute
();
$transaction
->
rollBack
();
$this
->
assertFalse
(
$transaction
->
isActive
);
$this
->
assertNull
(
$connection
->
transaction
);
$this
->
assertEquals
(
0
,
$connection
->
createCommand
(
"SELECT COUNT(*) FROM profile WHERE description = 'test transaction';"
)
->
queryScalar
());
$transaction
=
$connection
->
beginTransaction
();
$connection
->
createCommand
()
->
insert
(
'profile'
,
[
'description'
=>
'test transaction'
])
->
execute
();
$transaction
->
commit
();
$this
->
assertFalse
(
$transaction
->
isActive
);
$this
->
assertNull
(
$connection
->
transaction
);
$this
->
assertEquals
(
1
,
$connection
->
createCommand
(
"SELECT COUNT(*) FROM profile WHERE description = 'test transaction';"
)
->
queryScalar
());
}
public
function
testTransactionIsolation
()
{
$connection
=
$this
->
getConnection
(
true
);
$transaction
=
$connection
->
beginTransaction
(
Transaction
::
READ_UNCOMMITTED
);
$transaction
->
commit
();
$transaction
=
$connection
->
beginTransaction
(
Transaction
::
READ_COMMITTED
);
$transaction
->
commit
();
$transaction
=
$connection
->
beginTransaction
(
Transaction
::
REPEATABLE_READ
);
$transaction
->
commit
();
$transaction
=
$connection
->
beginTransaction
(
Transaction
::
SERIALIZABLE
);
$transaction
->
commit
();
}
}
tests/unit/framework/db/pgsql/PostgreSQLConnectionTest.php
View file @
6e0ee4ed
<?php
namespace
yiiunit\framework\db\pgsql
;
use
yii\db\Transaction
;
use
yiiunit\framework\db\ConnectionTest
;
/**
...
...
@@ -48,4 +49,29 @@ class PostgreSQLConnectionTest extends ConnectionTest
$this
->
assertEquals
(
'{{column}}'
,
$connection
->
quoteColumnName
(
'{{column}}'
));
$this
->
assertEquals
(
'(column)'
,
$connection
->
quoteColumnName
(
'(column)'
));
}
public
function
testTransactionIsolation
()
{
$connection
=
$this
->
getConnection
(
true
);
$transaction
=
$connection
->
beginTransaction
();
$transaction
->
setIsolationLevel
(
Transaction
::
READ_UNCOMMITTED
);
$transaction
->
commit
();
$transaction
=
$connection
->
beginTransaction
();
$transaction
->
setIsolationLevel
(
Transaction
::
READ_COMMITTED
);
$transaction
->
commit
();
$transaction
=
$connection
->
beginTransaction
();
$transaction
->
setIsolationLevel
(
Transaction
::
REPEATABLE_READ
);
$transaction
->
commit
();
$transaction
=
$connection
->
beginTransaction
();
$transaction
->
setIsolationLevel
(
Transaction
::
SERIALIZABLE
);
$transaction
->
commit
();
$transaction
=
$connection
->
beginTransaction
();
$transaction
->
setIsolationLevel
(
Transaction
::
SERIALIZABLE
.
' READ ONLY DEFERABLE'
);
$transaction
->
commit
();
}
}
tests/unit/framework/db/sqlite/SqliteConnectionTest.php
View file @
6e0ee4ed
<?php
namespace
yiiunit\framework\db\sqlite
;
use
yii\db\Transaction
;
use
yiiunit\framework\db\ConnectionTest
;
/**
...
...
@@ -45,4 +46,15 @@ class SqliteConnectionTest extends ConnectionTest
$this
->
assertEquals
(
'{{column}}'
,
$connection
->
quoteColumnName
(
'{{column}}'
));
$this
->
assertEquals
(
'(column)'
,
$connection
->
quoteColumnName
(
'(column)'
));
}
public
function
testTransactionIsolation
()
{
$connection
=
$this
->
getConnection
(
true
);
$transaction
=
$connection
->
beginTransaction
(
Transaction
::
READ_UNCOMMITTED
);
$transaction
->
rollBack
();
$transaction
=
$connection
->
beginTransaction
(
Transaction
::
SERIALIZABLE
);
$transaction
->
rollBack
();
}
}
Write
Preview
Markdown
is supported
0%
Try again
or
attach a new file
Attach a file
Cancel
You are about to add
0
people
to the discussion. Proceed with caution.
Finish editing this message first!
Cancel
Please
register
or
sign in
to comment