Nov 162011
 

Download as ebook

Transactions are the seat-belts of SQL servers. They protect our data by promising “all or nothing”. Data consistency on any level couldn’t be guaranteed without it. In a sense transactions work because they guarantee atomicity. They work because they allow you to abandon your changes and walk away at will, completely secure in the knowledge that not only your changes thus far aren’t visible to anyone, but also that your changes didn’t go anywhere near your valuable data.

Any reasonably-sized database code, therefore, is bound to have transactions peppered all about. Yet having a flawed implementation could be as worse as not having any at all. Perhaps even worse, given the false confidence. To my shock and horror, we just discovered a similar situation in one of our products. The opportunity to get to the bottom of transactions was pretty much forced, but it was a welcome opportunity nonetheless.

Here I’ll limit this investigation to MS SQL (2005 and 2008 used for testing).

Here is what we’re trying to achieve:

  1. Understand how MS SQL transactions work.
  2. Transactions must support nesting and rollback should abort all.
  3. Develop a template that use transactions correctly with error handling.

Test Bed

Let’s start by a boilerplate database as a test-bed.

-- Create an uncreatively named database.
CREATE DATABASE DeeBee
GO
USE DeeBee
GO

-- Create a table to use for data modification.
CREATE TABLE Tee(
	-- We'll generate overflow exception at will using this field.
	Num TINYINT
)
GO

Now let’s see what happens if we do multiple inserts and one fails…

-- Sproc to do multiple inserts with failure.
CREATE PROCEDURE [Multi_Insert]
AS
	-- Normal case
	INSERT INTO Tee VALUES(1);
	-- Overflow case
	INSERT INTO Tee VALUES(2000);
	-- Normal case again
	INSERT INTO Tee VALUES(3);
GO

To execute the above sproc, run the following (repeat after each change to the sproc above):

-- Clean slate.
DELETE FROM Tee
GO

-- Execute complex statements.
EXEC Multi_Insert;
GO

-- Check the results
SELECT * FROM Tee
GO

Results (for the exec alone):

(1 row(s) affected)
Msg 220, Level 16, State 2, Procedure Multi_Insert, Line 8
Arithmetic overflow error for data type tinyint, value = 2000.
The statement has been terminated.

(1 row(s) affected)

Two things to observe here: First, unsurprisingly the first insert went as planned as can be seen in the first “1 row(s) affected” message, followed by the overflow error. Second, which is important here, is that this didn’t abort or change the flow of the sproc, rather, the 3rd insert was executed as well.

Selecting everything in the Tee gives us:

1
3

Error Handling

In many cases we wouldn’t want to resume with our operations when one fails. A quick solution might look something like this:

-- Sproc to do multiple inserts with failure.
ALTER PROCEDURE [Multi_Insert]
AS
	-- Normal case
	INSERT INTO Tee VALUES(1);
	if @@ERROR <> 0
		RETURN

	-- Overflow case
	INSERT INTO Tee VALUES(2000);
	if @@ERROR <> 0
		RETURN

	-- Normal case again
	INSERT INTO Tee VALUES(3);
GO

This would work, but it only prevents further operations after the initial error, it doesn’t undo previous changes. In addition, it’s very tedious, especially with complex sprocs and looks ugly. Let’s see what we can do with exception handling…

-- Sproc to do multiple inserts with failure.
ALTER PROCEDURE [Multi_Insert]
AS
BEGIN TRY
	-- Normal case
	INSERT INTO Tee VALUES(1);
	-- Overflow case
	INSERT INTO Tee VALUES(2000);
	-- Normal case again
	INSERT INTO Tee VALUES(3);
END TRY
BEGIN CATCH
	PRINT ERROR_MESSAGE();
END CATCH
GO

This is functionally equivalent to the previous version, however here we have a clean control-flow and no longer do we need to taint our code with error checking. The print statement isn’t necessary, I just added it to show that the same error occurs. The result of this sproc is a single insert into Tee with the value 1.

Transactions

Let’s do the same, this time using transactions only.

-- Sproc to do multiple inserts with failure.
ALTER PROCEDURE [Multi_Insert]
AS
BEGIN
	BEGIN TRANSACTION
		-- Normal case
		INSERT INTO Tee VALUES(1);
		-- Overflow case
		INSERT INTO Tee VALUES(2000);
		-- Normal case again
		INSERT INTO Tee VALUES(3);
	COMMIT TRANSACTION
END
GO

The above sproc will result in the following, familiar, output:

(1 row(s) affected)
Msg 220, Level 16, State 2, Procedure Multi_Insert, Line 9
Arithmetic overflow error for data type tinyint, value = 2000.
The statement has been terminated.

(1 row(s) affected)

This is the exact same behavior as without the transactions! This means transactions don’t automatically add protection, recovery and undo. Not only didn’t we revert the first insert after the error, but we went on to execute the remainder of the transaction. The only way to fix this is to actually issue a ROLLBACK TRANSACTION statement. Of course we must do this by first detecting that something went wrong. Since we already know that we must do this manually, we should either check for errors or wrap the code in TRY/CATCH clauses.

-- Sproc to do multiple inserts with failure.
ALTER PROCEDURE [Multi_Insert]
AS
BEGIN TRY
	BEGIN TRANSACTION
		-- Normal case
		INSERT INTO Tee VALUES(1);
		-- Overflow case
		INSERT INTO Tee VALUES(2000);
		-- Normal case again
		INSERT INTO Tee VALUES(3);
	COMMIT TRANSACTION
END TRY
BEGIN CATCH
	ROLLBACK TRANSACTION
	PRINT ERROR_MESSAGE();
END CATCH
GO

Results:

(1 row(s) affected)

(0 row(s) affected)
Arithmetic overflow error for data type tinyint, value = 2000.

Finally, modifications are rolled back and the table is back to a clean slate, as it was before executing the sproc.

Nested Transactions

Now that we have a working transaction with correct exception handling, let’s try to develop a version that is symmetric and can be nested. We could use the above try/transaction/catch/rollback pattern, except, it’s not robust. To see why that is so, let’s take a little bit more complex case. Suppose you used this pattern in the sprocs that do modification, and in one case you called one sproc from another.

-- Sproc that does complex operations.
CREATE PROCEDURE [SP_Complex]
AS
BEGIN TRY
	BEGIN TRANSACTION

		-- Normal case
		INSERT INTO Tee VALUES(0);

		-- Execute a bad sproc.
		EXEC Multi_Insert;

		-- Normal case again
		INSERT INTO Tee VALUES(5);
	COMMIT TRANSACTION
END TRY
BEGIN CATCH
	ROLLBACK TRANSACTION
	PRINT ERROR_MESSAGE();
END CATCH
GO

The above sproc is written using the same pattern we used in Multi_Insert. We know the inner Multi_Insert will have an exception, it’ll rollback the transaction and return. But what about the outer transaction in SP_Complex? Would the first insert be rolled back? Will the last insert get executed?

Results:

(1 row(s) affected)

(1 row(s) affected)

(0 row(s) affected)
Arithmetic overflow error for data type tinyint, value = 2000.
Msg 3903, Level 16, State 1, Procedure SP_Complex, Line 19
The ROLLBACK TRANSACTION request has no corresponding BEGIN TRANSACTION.
Transaction count after EXECUTE indicates that a COMMIT or ROLLBACK TRANSACTION statement is missing. Previous count = 1, current count = 0.

Things didn’t go as planned. Checking for modifications in the Tee table shows that indeed the transaction worked as expected and all changes were rolled back. We still got an error though! To understand what’s going on, let’s see what the error was about.

First, notice that there were two inserts, one happened in the outer transaction and the second from the inner one, yet both were rolled back (the table should be empty). Then we print the overflow error, which indicates that the second insert in Multi_Insert threw. So far, so good. Then we hit an unanticipated error message. The clue to what happened is in “Transaction count after EXECUTE […]”. It seems that SQL engine is checking for transaction count after EXEC statements. Since we called ROLLBACK in Multi_Insert it seems that this has rolled back not only the inner transaction, but also the outer. This is confirmed by two facts. First, the table hasn’t been changed and all our inserts have been undone. Second, the inner ROLLBACK does match the BEGIN TRANSACTION in Multi_Insert and so does the pair in SP_Complex. So the only way we could get a mismatch error is if something in Multi_Insert had an effect larger than its scope. (Also, what’s with “Transaction count” references?)

To see what actually happened, let’s trace the execution path:

-- Sproc to do multiple inserts with failure.
ALTER PROCEDURE [Multi_Insert]
AS
BEGIN TRY
	BEGIN TRANSACTION
		PRINT 'IN [Multi_Insert]. Transactions: ' + Convert(varchar, @@TRANCOUNT);
		-- Normal case
		INSERT INTO Tee VALUES(1);
		-- Overflow case
		INSERT INTO Tee VALUES(2000);
		-- Normal case again
		INSERT INTO Tee VALUES(3);
	COMMIT TRANSACTION
END TRY
BEGIN CATCH
	PRINT 'ERR [Multi_Insert]: ' + ERROR_MESSAGE();
	ROLLBACK TRANSACTION
	PRINT 'Rolled back. Transactions: ' + Convert(varchar, @@TRANCOUNT);
END CATCH
GO

-- Sproc that does complex operations.
ALTER PROCEDURE [SP_Complex]
AS
BEGIN TRY
	BEGIN TRANSACTION
		PRINT 'IN [SP_Complex]. Transactions: ' + Convert(varchar,@@TRANCOUNT);

		-- Normal case
		INSERT INTO Tee VALUES(0);

		-- Execute a bad sproc.
		EXEC Multi_Insert;

		-- Normal case again
		INSERT INTO Tee VALUES(5);
	COMMIT TRANSACTION
END TRY
BEGIN CATCH
	PRINT 'ERR [SP_Complex]: ' + ERROR_MESSAGE();
	ROLLBACK TRANSACTION
	PRINT 'Rolled back. Transactions: ' + Convert(varchar, @@TRANCOUNT);
END CATCH
GO

Results:

IN [SP_Complex]. Transactions: 1

(1 row(s) affected)
IN [Multi_Insert]. Transactions: 2

(1 row(s) affected)

(0 row(s) affected)
ERR [Multi_Insert]: Arithmetic overflow error for data type tinyint, value = 2000.
Rolled back. Transactions: 0
ERR [SP_Complex]: Transaction count after EXECUTE indicates that a COMMIT or ROLLBACK TRANSACTION statement is missing. Previous count = 1, current count = 0.
Msg 3903, Level 16, State 1, Procedure SP_Complex, Line 21
The ROLLBACK TRANSACTION request has no corresponding BEGIN TRANSACTION.
Rolled back. Transactions: 0

To get the transaction count we use @@TRANCOUNT. Now if we look at the output from the trace, we’ll see the exact same thing, except now it’s obvious that the transaction count is at 2 within the inner transaction, yet after catching the overflow exception and rolling back, the transaction count has dropped to 0! This confirms it. ROLLBACK works not only on the current transaction, but escalates all the way to the top-most transaction. The references to the “Previous count = 1, current count = 0.” is regarding the transaction count before the EXEC statement and after it. The ROLLBACK in Multi_Insert made both the COMMIT and ROLLBACK statements in SP_Complex obsolete, or rather invalid.

Correct Nesting

-- Sproc to do multiple inserts with failure.
ALTER PROCEDURE [Multi_Insert]
AS
BEGIN TRY
	BEGIN TRANSACTION
		PRINT 'IN [Multi_Insert]. Transactions: ' + Convert(varchar, @@TRANCOUNT);
		-- Normal case
		INSERT INTO Tee VALUES(1);
		-- Overflow case
		INSERT INTO Tee VALUES(2000);
		-- Normal case again
		INSERT INTO Tee VALUES(3);
	COMMIT TRANSACTION
END TRY
BEGIN CATCH
	PRINT 'ERR [Multi_Insert]: ' + ERROR_MESSAGE();
	IF (@@TRANCOUNT > 0)
		ROLLBACK TRANSACTION
	PRINT 'Rolled back. Transactions: ' + Convert(varchar, @@TRANCOUNT);
END CATCH
GO

-- Sproc that does complex operations.
ALTER PROCEDURE [SP_Complex]
AS
BEGIN TRY
	BEGIN TRANSACTION
		PRINT 'IN [SP_Complex]. Transactions: ' + Convert(varchar, @@TRANCOUNT);

		-- Normal case
		INSERT INTO Tee VALUES(0);

		-- Execute a bad sproc.
		EXEC Multi_Insert;

		-- Normal case again
		INSERT INTO Tee VALUES(5);
	COMMIT TRANSACTION
END TRY
BEGIN CATCH
	PRINT 'ERR [SP_Complex]: ' + ERROR_MESSAGE();
	IF (@@TRANCOUNT > 0)
		ROLLBACK TRANSACTION
	PRINT 'Rolled back. Transactions: ' + Convert(varchar, @@TRANCOUNT);
END CATCH
GO

By checking whether or not an inner transaction has rolled back already we avoid any mismatches. This works because using try/catch errors always execute the catch clauses, preventing any statements after the error to execute. If our transactions catch an exception, yet the @@TRANCOUNT is 0, then we must conclude that an inner sproc has made more commits than the transactions it created, or it rolled back the transaction(s). In both cases we must not ROLLBACK unless we have a valid transaction, and we must always ROLLBACK if we’re in a CATCH clause if we have a valid transaction. Notice that we don’t check for @@TRANCOUNT to COMMIT TRANSACTION. The reason is because the only case where we could get to it is when the execution of the previous statements are successful. True that if somewhere a mismatched COMMIT is done, we’ll get a mismatch, but that’s a programmer error and must not be suppressed. That is, by suppressing that case, our code will not work as expected (in a transaction) because all subsequent statements will execute outside transactions, and therefore can’t be rolled back. So we let that mismatch blow up.

The Template

So, now that we have a good understanding of how transactions and error handling works, we can finally create a template that we can reuse, safe in the knowledge that it’s nestable and will behave as expected in all cases.

BEGIN TRY
	BEGIN TRANSACTION

	--
	-- YOUR CODE HERE
	--

	-- Don't check for mismatching. Such an error is fatal.
	COMMIT TRANSACTION
END TRY
BEGIN CATCH
	-- An inner sproc might have rolled-back already.
	IF (@@TRANCOUNT > 0)
		ROLLBACK TRANSACTION
END CATCH

Full test-bed for reference:

IF EXISTS(SELECT * FROM sys.sysdatabases where name='DeeBee')
DROP DATABASE DeeBee
GO

-- Create an uncreatively named database.
CREATE DATABASE DeeBee
GO
USE DeeBee
GO

-- Create a table to use for data modification.
CREATE TABLE Tee(
	-- We'll generate overflow exception at will using this field.
	Num TINYINT
)
GO


-- Sproc to do multiple inserts with failure.
CREATE PROCEDURE [Multi_Insert]
AS
BEGIN TRY
	BEGIN TRANSACTION
		PRINT 'IN [Multi_Insert]. Transactions: ' + Convert(varchar, @@TRANCOUNT);
		-- Normal case
		INSERT INTO Tee VALUES(1);
		-- Overflow case
		INSERT INTO Tee VALUES(2000);
		-- Normal case again
		INSERT INTO Tee VALUES(3);
	COMMIT TRANSACTION
END TRY
BEGIN CATCH
	PRINT 'ERR [Multi_Insert]: ' + ERROR_MESSAGE();
	IF (@@TRANCOUNT > 0)
		ROLLBACK TRANSACTION
	PRINT 'Rolled back. Transactions: ' + Convert(varchar, @@TRANCOUNT);
END CATCH
GO

-- Sproc that does complex operations.
CREATE PROCEDURE [SP_Complex]
AS
BEGIN TRY
	BEGIN TRANSACTION
		PRINT 'IN [SP_Complex]. Transactions: ' + Convert(varchar, @@TRANCOUNT);

		-- Normal case
		INSERT INTO Tee VALUES(0);

		-- Execute a bad sproc.
		EXEC Multi_Insert;

		-- Normal case again
		INSERT INTO Tee VALUES(5);
	COMMIT TRANSACTION
END TRY
BEGIN CATCH
	PRINT 'ERR [SP_Complex]: ' + ERROR_MESSAGE();
	IF (@@TRANCOUNT > 0)
		ROLLBACK TRANSACTION
	PRINT 'Rolled back. Transactions: ' + Convert(varchar, @@TRANCOUNT);
END CATCH
GO

-- Clean slate.
DELETE FROM Tee
GO

-- Execute complex statements.
--EXEC Multi_Insert;
EXEC SP_Complex;
GO

-- Check the results
SELECT * FROM Tee
GO

Conclusion

Error handling is often tricky and full of gotcha’s. We should be careful not to make any unwarranted assumptions, especially when working cross-languages. The error handling, and more importantly transactions, in SQL don’t necessarily behave like your favorite programming language. By carefully reading documentation, experimenting and adding traces we can get insight and develop robust solutions.

However the above isn’t the last word on error handling or transactions. Your needs might be different and your use-cases might dictate other priorities. Perhaps my approach misses some subtle case that you can’t afford to ignore. Or may be this is good enough for a boilerplate template. Either way, comments, corrections and suggestions are more than welcome.

Download as ebook

Share

  21 Responses to “Understanding MS SQL Transactions and Error Handling”

  1. Nice article. Could you clarify how the nested COMMITs work in MS SQL? Since a nested ROLLBACK rolls everything back, I’d guess that a nested COMMIT commits everything. Or is it smart enough to only commit the stuff inside the inner transaction? Or does it just update the transcount and not actually commit anything?

    E.g. suppose that Multi_Insert executes without errors, but there’s an error in SP_Complex after the call to Multi_Insert. If the inner COMMIT actually commits anything, it seems your template does not work “as expected”.

    Like or Dislike: Thumb up 0 Thumb down 0 (0)

    • Mikko,

      The short answer is that it’s smart enough. Basically a COMMIT will update the transcount by reducing it if it’s larger than 0 and it will commit the changes if it’s exactly 0.

      The only things that matter are the following:

      1) COMMIT and ROLLBACK must have a matching BEGIN statement (so you can do as many COMMITs as you like, so long that you don’t do any more than the number of BEGINs you had done thus far.

      2) EXEC checks that you do maintain the correct transcount across it (so you can’t leave an sproc with a mismatched BEGIN and COMMIT statements).

      3) ROLLBACK goes all the way to the top-most BEGIN and the COMMIT that drops transcount to 0 actually commits the data.

      As an example, suppose SP_Complex begins a transaction, inserts a row. It then calls Multi_Insert which simply COMMITs and returns. Two things will happen: First, the COMMIT within Multi_Insert will reduce the transcount to 0 and actually commit the inserted row in SP_Complex (even though the BEGIN was in another sproc). On return to SP_Complex, Multi_Insert will have violated the transcount and will throw an exception. Now, even if SP_Complex catches this exception and attempts ROLLBACK, the inserted row will not be undone. In fact, it can only raise yet another exception: A mismatched ROLLBACK without BEGIN.

      HTH

      Like or Dislike: Thumb up 0 Thumb down 0 (0)

  2. Very good article. There were a few things you introduced about transactions that I didn’t know. However, after experimenting a bit, I wonder if you recommend putting a THROW statement inside the CATCH blocks. Otherwise, the transaction rolls back, but the sp says that commands completed successfully.

    Like or Dislike: Thumb up 1 Thumb down 0 (+1)

  3. hi,
    i think that in Nested Transaction there might be a problem in the commit .
    because if you do commit to the inner transaction you do commit for all transaction include the warped one .
    here is the solution for it:
    http://rusanu.com/2009/06/11/exception-handling-and-nested-transactions/

    Like or Dislike: Thumb up 1 Thumb down 0 (+1)

  4. Thank you – very well written, most helpful.

    Like or Dislike: Thumb up 0 Thumb down 0 (0)

  5. Very good article…it has explained transaction so well to me. Thanks for sharing.

    Like or Dislike: Thumb up 0 Thumb down 0 (0)

  6. Objective #2 is wrong: rollback should not abort all, it should only roll back the nested transaction (the local work) and throw an error, then it should be up to the caller whether to roll back their own work and throw an error or let their own work stand. Once you’ve worked it out and created a new template I’d be good if you’d let us know.

    Like or Dislike: Thumb up 0 Thumb down 0 (0)

    • I suspect you are alluding to named transactions. Well, if that is the case, I’m afraid it won’t work.

      I don’t know what solution you have in mind, but to my knowledge MS SQL transactions always rollback the *outermost* transaction, even when named. In fact, read what the documentation says[1]:

      “When nesting transactions,transaction_name must be the name from the outermost BEGIN TRANSACTION statement.”

      Also:

      “When nesting transactions, this same statement rolls back all inner transactions to the outermost BEGIN TRANSACTION statement.”

      Conclusion: MS SQL insures that it’s all or nothing. Nesting transactions doesn’t isolate inner transactions from outer ones. It’s all really one big transaction and any failure will force everything out. This is the point of the article and my solution is to avoid rollback when an inner transaction has already done so.

      Now, if you have some solution around this, I’d be happy to learn about it. But quite honestly, my design requirements are in line with exactly what MS SQL is already doing. That is, I wouldn’t want inner transaction rollback while committing outer transactions. There is reason the outer one is done in a transaction and calling SP that hides exceptions by local rollback is simply a bad idea. There should be no exception suppression within transactions, unless everything is rolled back.

      [1] http://technet.microsoft.com/en-us/library/ms181299.aspx

      -Ash

      Like or Dislike: Thumb up 1 Thumb down 0 (+1)

  7. You censored my earlier comment because I challenged your premises. I hope that that’s not the way you always deal with challenges, that’d be sad. #2 is wrong because any command that fails should roll itself back, not bring the whole system down. If you have included #2 because you don’t think a solution would be possible without it, fine, admit your limitations and say so. But if you live up to the challenge you should keep my comments in and try to improve your solution, as I suggested you’d do, or ask me or some other contributor to tell you how that’s possible. I will not tell you how, even though I know. I’m not here to help write your articles for you, but I am here to give you feedback. My feedback on your solution is that it is incomplete, my feedback on you personally is that censoring feedback that disagrees with you is not the way to deal with problems. It may help to keep your blog tidy but it won’t help you or anybody else improve.

    Like or Dislike: Thumb up 0 Thumb down 0 (0)

    • On the other hand if my earlier comment 241752 does turn up I will know I was wrong about the censure bit. In that case, my admission would be your apology.

      To paraphrase your article and my feedback, I would be “rolling myself back” but only partially, i.e., only as to what went wrong and the error was concerned, not about the whole of my work, a part of which will still stand.

      Besides if we’re trapping errors is probably to remediate them, not to trap and say ‘shutdown system anyway’. A proc will never know if a parent has a way to deal with an error that the proc can only throw, for this reason, it should always respect the parent’s work, and not undo any work besides what the child proc itself has added in its own nested tran.

      Like or Dislike: Thumb up 0 Thumb down 0 (0)

    • Hi Jean,

      > You censored my earlier comment because I challenged your premises.
      Not at all. First posts by everyone is moderated. I have been busy lately so didn’t get a chance to go through my mail and comments. Apologies for that.

      > I will not tell you how, even though I know. I’m not here to help write your articles for you, but I am here to give you feedback.
      Well, I’m not getting paid to write anything. So neither of us is obliged to anything :)
      If you share what you know, as I did, we might all learn something. Otherwise, I’m happy with my limited knowledge and broken solutions. It’s the best I can do until I learn better.

      Cheers!

      Like or Dislike: Thumb up 1 Thumb down 0 (+1)

      • You have been good-natured in your replies and I see you weren’t censoring. Humble pie for me please. Jean

        Like or Dislike: Thumb up 0 Thumb down 0 (0)

  8. There is a indeed solution to this that does away with #2 . I have scratched my head for too long before I found it. Yes, it has to do with named transactions but it is not straightforward, one needs to “algebrize them” in a certain way. I will share soon.

    Like or Dislike: Thumb up 0 Thumb down 0 (0)

  9. Ashod,

    Thanks for the detailed article. I admire your writing style. Keep it up !!

    Just a few minutes ago, I copied your complete template and ran it in my lab environment. I got the same error that it is supposed to avoid.

    Error Message:
    ERR [SP_Complex]: Transaction count after EXECUTE indicates a mismatching number of BEGIN and COMMIT statements. Previous count = 1, current count = 0.

    I’m using Sql 2008 R2, if it helps.

    The complete output looks like this:

    (0 row(s) affected)
    IN [SP_Complex]. Transactions: 1

    (1 row(s) affected)
    IN [Multi_Insert]. Transactions: 2

    (1 row(s) affected)

    (0 row(s) affected)
    ERR [Multi_Insert]: Arithmetic overflow error for data type tinyint, value = 2000.
    Rolled back. Transactions: 0
    ERR [SP_Complex]: Transaction count after EXECUTE indicates a mismatching number of BEGIN and COMMIT statements. Previous count = 1, current count = 0.
    Rolled back. Transactions: 0

    (1 row(s) affected)

    (0 row(s) affected)

    Am I missing something?

    Thanks,
    _SqlTimes

    Like or Dislike: Thumb up 0 Thumb down 0 (0)

  10. […] articulated as the managers of the data. These transactions perform a twofold role. First, these transactions guarantee data consistency and secondly it allows one to discard the changes without making them visible to anyone and without […]

    Like or Dislike: Thumb up 0 Thumb down 0 (0)

  11. […] articulated as the managers of the data. These transactions perform a twofold role. First, these transactions guarantee data consistency and secondly it allows one to discard the changes without making them visible to anyone and without […]

    Like or Dislike: Thumb up 0 Thumb down 0 (0)

 Leave a Reply

You may use these HTML tags and attributes: <a href="" title=""> <abbr title=""> <acronym title=""> <b> <blockquote cite=""> <cite> <code> <del datetime=""> <em> <i> <q cite=""> <s> <strike> <strong>

(required)

(required, not public)

 

QR Code Business Card