Click here to monitor SSC
SQLServerCentral is supported by Redgate
 
Log in  ::  Register  ::  Not logged in
 
 
 


Adding unique int key using max


Adding unique int key using max

Author
Message
tshad
tshad
SSC-Enthusiastic
SSC-Enthusiastic (190 reputation)SSC-Enthusiastic (190 reputation)SSC-Enthusiastic (190 reputation)SSC-Enthusiastic (190 reputation)SSC-Enthusiastic (190 reputation)SSC-Enthusiastic (190 reputation)SSC-Enthusiastic (190 reputation)SSC-Enthusiastic (190 reputation)

Group: General Forum Members
Points: 190 Visits: 454
I am trying to add multiple records to my table (insert/select).


INSERT INTO Users
( User_id ,
Name
)
SELECT ( SELECT MAX(User_id) + 1
FROM Users
) ,
Name



But I get the error:

Violation of PRIMARY KEY constraint 'PK_Users'. Cannot insert duplicate key in object 'dbo.Users'.

But I am using the max User_id + 1, so it can't be duplicate

This would insert about 20 records.

Why the error?

Thanks,

Tom
Eirikur Eiriksson
Eirikur Eiriksson
SSCertifiable
SSCertifiable (6.8K reputation)SSCertifiable (6.8K reputation)SSCertifiable (6.8K reputation)SSCertifiable (6.8K reputation)SSCertifiable (6.8K reputation)SSCertifiable (6.8K reputation)SSCertifiable (6.8K reputation)SSCertifiable (6.8K reputation)

Group: General Forum Members
Points: 6820 Visits: 17766
tshad (7/31/2014)
I am trying to add multiple records to my table (insert/select).


INSERT INTO Users
( User_id ,
Name
)
SELECT ( SELECT MAX(User_id) + 1
FROM Users
) ,
Name



But I get the error:

Violation of PRIMARY KEY constraint 'PK_Users'. Cannot insert duplicate key in object 'dbo.Users'.

But I am using the max User_id + 1, so it can't be duplicate

This would insert about 20 records.

Why the error?

Thanks,

Tom

Try something like (untested but certain it works ;-)
Cool
     INSERT INTO Users
( User_id ,
Name
)
SELECT ROW_NUMBER() OVER (ORDER BY (SELECT NULL)) + ( SELECT MAX(User_id)
FROM Users
) ,
Name


autoexcrement
autoexcrement
SSC Veteran
SSC Veteran (204 reputation)SSC Veteran (204 reputation)SSC Veteran (204 reputation)SSC Veteran (204 reputation)SSC Veteran (204 reputation)SSC Veteran (204 reputation)SSC Veteran (204 reputation)SSC Veteran (204 reputation)

Group: General Forum Members
Points: 204 Visits: 777
To further explain things (hopefully correctly), the reason your SQL was failing was that it was determining the MAX value once, and adding 1 to it once, and attempting to use that same value for each of the 20 new records you were inserting. Make sense?

I'd guess that if you used your method to insert 1 record, it would work fine.


"If I had been drinking out of that toilet, I might have been killed." -Ace Ventura
tshad
tshad
SSC-Enthusiastic
SSC-Enthusiastic (190 reputation)SSC-Enthusiastic (190 reputation)SSC-Enthusiastic (190 reputation)SSC-Enthusiastic (190 reputation)SSC-Enthusiastic (190 reputation)SSC-Enthusiastic (190 reputation)SSC-Enthusiastic (190 reputation)SSC-Enthusiastic (190 reputation)

Group: General Forum Members
Points: 190 Visits: 454
That worked fine.

Not sure what this means:

ROW_NUMBER() OVER (ORDER BY (SELECT NULL))

How does that work?
Eirikur Eiriksson
Eirikur Eiriksson
SSCertifiable
SSCertifiable (6.8K reputation)SSCertifiable (6.8K reputation)SSCertifiable (6.8K reputation)SSCertifiable (6.8K reputation)SSCertifiable (6.8K reputation)SSCertifiable (6.8K reputation)SSCertifiable (6.8K reputation)SSCertifiable (6.8K reputation)

Group: General Forum Members
Points: 6820 Visits: 17766
tshad (8/1/2014)
That worked fine.

Not sure what this means:

ROW_NUMBER() OVER (ORDER BY (SELECT NULL))

How does that work?


This adds an incremental number to the output, by stating (SELECT NULL), one indicates that the order is not implied by any values but only the order of appearance. So for each row returned, the id value will be the MAX(KEY) (static throughout the batch) + the incremental row number.
Cool
Eirikur Eiriksson
Eirikur Eiriksson
SSCertifiable
SSCertifiable (6.8K reputation)SSCertifiable (6.8K reputation)SSCertifiable (6.8K reputation)SSCertifiable (6.8K reputation)SSCertifiable (6.8K reputation)SSCertifiable (6.8K reputation)SSCertifiable (6.8K reputation)SSCertifiable (6.8K reputation)

Group: General Forum Members
Points: 6820 Visits: 17766
CELKO (8/19/2014)
First learn that a row is not a record; this is a fundamental concept.

Next, look at CREATE SEQUENCE.


Hey Joe,
would you care to share a definition of the difference of the two?
Cool
Lowell
Lowell
SSChampion
SSChampion (14K reputation)SSChampion (14K reputation)SSChampion (14K reputation)SSChampion (14K reputation)SSChampion (14K reputation)SSChampion (14K reputation)SSChampion (14K reputation)SSChampion (14K reputation)

Group: General Forum Members
Points: 14984 Visits: 39009
CELKO (8/19/2014)
First learn that a row is not a record; this is a fundamental concept.

Next, look at CREATE SEQUENCE.


depends on what you are referring to;

taken at face value Wikipedia disagrees with that statement in the very first sentence of the definition
http://en.wikipedia.org/wiki/Row_(database)

http://en.wikipedia.org/wiki/Row_(database)
In the context of a relational database, a row—also called a record or tuple —represents a single, implicitly structured data item in a table. In simple terms, a database table can be thought of as consisting of rows and columns or fields.[1] Each row in a table represents a set of related data, and every row in the table has the same structure.


Lowell

--
help us help you! If you post a question, make sure you include a CREATE TABLE... statement and INSERT INTO... statement into that table to give the volunteers here representative data. with your description of the problem, we can provide a tested, verifiable solution to your question! asking the question the right way gets you a tested answer the fastest way possible!

Eirikur Eiriksson
Eirikur Eiriksson
SSCertifiable
SSCertifiable (6.8K reputation)SSCertifiable (6.8K reputation)SSCertifiable (6.8K reputation)SSCertifiable (6.8K reputation)SSCertifiable (6.8K reputation)SSCertifiable (6.8K reputation)SSCertifiable (6.8K reputation)SSCertifiable (6.8K reputation)

Group: General Forum Members
Points: 6820 Visits: 17766
CELKO (8/19/2014)
would you care to share a definition of the difference of the two?


You'll be sorry; this is the short version :-D


Thank you for this and not at all sorry as this is what was missing from your previous post ;-) In my opinion, complete answers such as this one help the OP's building a better understanding of the subject. It also aids in battling certain growing ambiguity.
Cool
Go


Permissions

You can't post new topics.
You can't post topic replies.
You can't post new polls.
You can't post replies to polls.
You can't edit your own topics.
You can't delete your own topics.
You can't edit other topics.
You can't delete other topics.
You can't edit your own posts.
You can't edit other posts.
You can't delete your own posts.
You can't delete other posts.
You can't post events.
You can't edit your own events.
You can't edit other events.
You can't delete your own events.
You can't delete other events.
You can't send private messages.
You can't send emails.
You can read topics.
You can't vote in polls.
You can't upload attachments.
You can download attachments.
You can't post HTML code.
You can't edit HTML code.
You can't post IFCode.
You can't post JavaScript.
You can post emoticons.
You can't post or upload images.

Select a forum

































































































































































SQLServerCentral


Search