SQL Server Forums
Profile | Register | Active Topics | Members | Search | Forum FAQ
 
Register Now and get your question answered!
Username:
Password:
Save Password
Forgot your Password?

 All Forums
 SQL Server 2005 Forums
 Transact-SQL (2005)
 Max + 1 duplicated !!!!
 New Topic  Reply to Topic
 Printer Friendly
Author Previous Topic Topic Next Topic  

mrsqlserver
Starting Member

6 Posts

Posted - 04/12/2013 :  15:06:00  Show Profile  Reply with Quote
Hi

I have this code in my SP, it was working fine till one day i had high traffic, now i get duplications on RecNo!!!
please i RecNo is not the Primary Key

Am i doing anything wrong here!
anyway i can fix this?

--------------------------------------------
DECLARE @MaxNo bigint
SELECT @MaxNo=Max(RecNo) + 1 FROM Records

INSERT INTO Records (RecNo, RecName, RecDate)
SELECT @MaxNo, @RecName, @RecDate
--------------------------------------------

Edited by - mrsqlserver on 04/12/2013 15:15:58

russell
Pyro-ma-ni-yak

USA
5072 Posts

Posted - 04/12/2013 :  15:47:30  Show Profile  Visit russell's Homepage  Reply with Quote

BEGIN TRAN

DECLARE @MaxNo bigint
SELECT @MaxNo=Max(RecNo) + 1 FROM Records

INSERT INTO Records (RecNo, RecName, RecDate)
SELECT @MaxNo, @RecName, @RecDate

COMMIT

But a better way would be to make recNo an identity column and use scope_identity() to retrieve it
Go to Top of Page

robvolk
Most Valuable Yak

USA
15663 Posts

Posted - 04/12/2013 :  19:38:05  Show Profile  Visit robvolk's Homepage  Reply with Quote
And regardless of which technique you use, without a unique or primary key constraint on RecNo column, you will still have duplicates.
Go to Top of Page

Lamprey
Flowing Fount of Yak Knowledge

4614 Posts

Posted - 04/16/2013 :  18:26:38  Show Profile  Reply with Quote
I agree with russell that identity would be better. But, if you are going implement hacks, besides a transaction, you might also want to a WITH (TABLOCKX) hint to your Recods table when you select the max.
Go to Top of Page

LoztInSpace
Aged Yak Warrior

940 Posts

Posted - 04/16/2013 :  23:50:15  Show Profile  Reply with Quote
Pretty sure the transaction won't make any difference. You can still get the same answer in 2 sessions if you hit it at the right time.
Just use an identity and be done with it. The alternatives are messy, error prone and can drastically affect scalability and throughput because (assuming you get it right) you end up serialising all your transactions behind table locks.
Go to Top of Page

russell
Pyro-ma-ni-yak

USA
5072 Posts

Posted - 04/17/2013 :  01:20:32  Show Profile  Visit russell's Homepage  Reply with Quote
quote:
Originally posted by LoztInSpace

Pretty sure the transaction won't make any difference.



100% sure that it will. Not maybe. It will.

Edited by - russell on 04/17/2013 01:21:15
Go to Top of Page

SwePeso
Patron Saint of Lost Yaks

Sweden
30217 Posts

Posted - 04/17/2013 :  01:35:44  Show Profile  Visit SwePeso's Homepage  Reply with Quote
quote:
Originally posted by mrsqlserver

--------------------------------------------
DECLARE @MaxNo bigint
SELECT @MaxNo=Max(RecNo) + 1 FROM Records

INSERT INTO Records (RecNo, RecName, RecDate)
SELECT @MaxNo, @RecName, @RecDate
--------------------------------------------



The first error is that the MAX part doesn't care about which RecName you are using. It just takes the MAX RecNo, regardless of which RecName is used. Is this by design or by error?
Should RecNo follow RecName?



N 56°04'39.26"
E 12°55'05.63"
Go to Top of Page

LoztInSpace
Aged Yak Warrior

940 Posts

Posted - 04/17/2013 :  21:54:58  Show Profile  Reply with Quote
quote:
Originally posted by russell

quote:
Originally posted by LoztInSpace

Pretty sure the transaction won't make any difference.



100% sure that it will. Not maybe. It will.


I respectfully disagree. Now with added proof!
Do this:

create table records
(value int unique)
insert into records values(1)

Then run this code in 2 different sessions:


begin transaction

DECLARE @MaxNo bigint
SELECT @MaxNo=Max(value) + 1 FROM records
 select @MaxNo
WAITFOR DELAY '00:00:05'
INSERT INTO records (value)
SELECT @MaxNo

commit transaction



(1 row(s) affected)
Msg 2627, Level 14, State 1, Line 8
Violation of UNIQUE KEY constraint 'UQ__records__40BBEA3A36470DEF'. Cannot insert duplicate key in object 'records'. The duplicate key value is (2).
The statement has been terminated.

Because both sessions (correctly) read the same maximum value at the same time.
Go to Top of Page

russell
Pyro-ma-ni-yak

USA
5072 Posts

Posted - 04/19/2013 :  11:58:37  Show Profile  Visit russell's Homepage  Reply with Quote
I think you're right. I stand corrected.
Go to Top of Page
  Previous Topic Topic Next Topic  
 New Topic  Reply to Topic
 Printer Friendly
Jump To:
SQL Server Forums © 2000-2009 SQLTeam Publishing, LLC Go To Top Of Page
This page was generated in 0.11 seconds. Powered By: Snitz Forums 2000