Click here to monitor SSC
SQLServerCentral is supported by Red Gate Software Ltd.
 
Log in  ::  Register  ::  Not logged in
 
 
 
        
Home       Members    Calendar    Who's On


Add to briefcase

Adding unique int key using max Expand / Collapse
Author
Message
Posted Thursday, July 31, 2014 3:01 PM
SSC-Enthusiastic

SSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-Enthusiastic

Group: General Forum Members
Last Login: Saturday, May 16, 2015 3:21 PM
Points: 156, Visits: 372
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
Post #1598500
Posted Thursday, July 31, 2014 3:06 PM This worked for the OP Answer marked as solution
SSCarpal Tunnel

SSCarpal TunnelSSCarpal TunnelSSCarpal TunnelSSCarpal TunnelSSCarpal TunnelSSCarpal TunnelSSCarpal TunnelSSCarpal TunnelSSCarpal Tunnel

Group: General Forum Members
Last Login: Today @ 5:06 AM
Points: 4,038, Visits: 10,411
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

     INSERT INTO Users
( User_id ,
Name
)
SELECT ROW_NUMBER() OVER (ORDER BY (SELECT NULL)) + ( SELECT MAX(User_id)
FROM Users
) ,
Name

Post #1598504
Posted Thursday, July 31, 2014 3:55 PM


SSC-Enthusiastic

SSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-Enthusiastic

Group: General Forum Members
Last Login: 2 days ago @ 9:56 AM
Points: 168, Visits: 663
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
Post #1598523
Posted Friday, August 1, 2014 10:41 AM
SSC-Enthusiastic

SSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-Enthusiastic

Group: General Forum Members
Last Login: Saturday, May 16, 2015 3:21 PM
Points: 156, Visits: 372
That worked fine.

Not sure what this means:

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

How does that work?
Post #1598765
Posted Friday, August 1, 2014 11:34 AM
SSCarpal Tunnel

SSCarpal TunnelSSCarpal TunnelSSCarpal TunnelSSCarpal TunnelSSCarpal TunnelSSCarpal TunnelSSCarpal TunnelSSCarpal TunnelSSCarpal Tunnel

Group: General Forum Members
Last Login: Today @ 5:06 AM
Points: 4,038, Visits: 10,411
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.
Post #1598783
Posted Tuesday, August 19, 2014 12:33 PM
SSCarpal Tunnel

SSCarpal TunnelSSCarpal TunnelSSCarpal TunnelSSCarpal TunnelSSCarpal TunnelSSCarpal TunnelSSCarpal TunnelSSCarpal TunnelSSCarpal Tunnel

Group: General Forum Members
Last Login: Today @ 5:06 AM
Points: 4,038, Visits: 10,411
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?
Post #1605117
Posted Tuesday, August 19, 2014 12:37 PM


SSChampion

SSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampion

Group: General Forum Members
Last Login: Today @ 8:20 AM
Points: 13,569, Visits: 34,526
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

--There is no spoon, and there's no default ORDER BY in sql server either.
Actually, Common Sense is so rare, it should be considered a Superpower. --my son
Post #1605125
Posted Tuesday, August 19, 2014 10:19 PM
SSCarpal Tunnel

SSCarpal TunnelSSCarpal TunnelSSCarpal TunnelSSCarpal TunnelSSCarpal TunnelSSCarpal TunnelSSCarpal TunnelSSCarpal TunnelSSCarpal Tunnel

Group: General Forum Members
Last Login: Today @ 5:06 AM
Points: 4,038, Visits: 10,411
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


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.

Post #1605278
« Prev Topic | Next Topic »

Add to briefcase

Permissions Expand / Collapse