Author |
Topic |
mrsqlserver
Starting Member
6 Posts |
Posted - 2013-04-12 : 15:06:00
|
HiI 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 KeyAm i doing anything wrong here!anyway i can fix this?--------------------------------------------DECLARE @MaxNo bigintSELECT @MaxNo=Max(RecNo) + 1 FROM RecordsINSERT INTO Records (RecNo, RecName, RecDate)SELECT @MaxNo, @RecName, @RecDate-------------------------------------------- |
|
russell
Pyro-ma-ni-yak
5072 Posts |
Posted - 2013-04-12 : 15:47:30
|
[code]BEGIN TRANDECLARE @MaxNo bigintSELECT @MaxNo=Max(RecNo) + 1 FROM RecordsINSERT INTO Records (RecNo, RecName, RecDate)SELECT @MaxNo, @RecName, @RecDateCOMMIT[/code]But a better way would be to make recNo an identity column and use scope_identity() to retrieve it |
|
|
robvolk
Most Valuable Yak
15732 Posts |
Posted - 2013-04-12 : 19:38:05
|
And regardless of which technique you use, without a unique or primary key constraint on RecNo column, you will still have duplicates. |
|
|
Lamprey
Master Smack Fu Yak Hacker
4614 Posts |
Posted - 2013-04-16 : 18:26:38
|
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. |
|
|
LoztInSpace
Aged Yak Warrior
940 Posts |
Posted - 2013-04-16 : 23:50:15
|
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. |
|
|
russell
Pyro-ma-ni-yak
5072 Posts |
Posted - 2013-04-17 : 01:20:32
|
quote: Originally posted by LoztInSpace Pretty sure the transaction won't make any difference.
100% sure that it will. Not maybe. It will. |
|
|
SwePeso
Patron Saint of Lost Yaks
30421 Posts |
Posted - 2013-04-17 : 01:35:44
|
quote: Originally posted by mrsqlserver --------------------------------------------DECLARE @MaxNo bigintSELECT @MaxNo=Max(RecNo) + 1 FROM RecordsINSERT 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" |
|
|
LoztInSpace
Aged Yak Warrior
940 Posts |
Posted - 2013-04-17 : 21:54:58
|
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 transactionDECLARE @MaxNo bigintSELECT @MaxNo=Max(value) + 1 FROM records select @MaxNoWAITFOR DELAY '00:00:05'INSERT INTO records (value)SELECT @MaxNocommit transaction (1 row(s) affected)Msg 2627, Level 14, State 1, Line 8Violation 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. |
|
|
russell
Pyro-ma-ni-yak
5072 Posts |
Posted - 2013-04-19 : 11:58:37
|
I think you're right. I stand corrected. |
|
|
|