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: Wednesday, September 3, 2014 11:46 AM
Points: 147, Visits: 361
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
SSCrazy

SSCrazySSCrazySSCrazySSCrazySSCrazySSCrazySSCrazySSCrazy

Group: General Forum Members
Last Login: Today @ 12:59 AM
Points: 2,417, Visits: 6,692
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: Friday, November 21, 2014 4:46 PM
Points: 157, Visits: 607
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: Wednesday, September 3, 2014 11:46 AM
Points: 147, Visits: 361
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
SSCrazy

SSCrazySSCrazySSCrazySSCrazySSCrazySSCrazySSCrazySSCrazy

Group: General Forum Members
Last Login: Today @ 12:59 AM
Points: 2,417, Visits: 6,692
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 11:12 AM


SSCommitted

SSCommittedSSCommittedSSCommittedSSCommittedSSCommittedSSCommittedSSCommittedSSCommitted

Group: General Forum Members
Last Login: Tuesday, November 18, 2014 12:29 PM
Points: 1,945, Visits: 3,121
First learn that a row is not a record; this is a fundamental concept.

Next, look at CREATE SEQUENCE.


Books in Celko Series for Morgan-Kaufmann Publishing
Analytics and OLAP in SQL
Data and Databases: Concepts in Practice
Data, Measurements and Standards in SQL
SQL for Smarties
SQL Programming Style
SQL Puzzles and Answers
Thinking in Sets
Trees and Hierarchies in SQL
Post #1605039
Posted Tuesday, August 19, 2014 12:33 PM
SSCrazy

SSCrazySSCrazySSCrazySSCrazySSCrazySSCrazySSCrazySSCrazy

Group: General Forum Members
Last Login: Today @ 12:59 AM
Points: 2,417, Visits: 6,692
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: Yesterday @ 2:39 PM
Points: 12,923, Visits: 32,313
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 8:37 PM


SSCommitted

SSCommittedSSCommittedSSCommittedSSCommittedSSCommittedSSCommittedSSCommittedSSCommitted

Group: General Forum Members
Last Login: Tuesday, November 18, 2014 12:29 PM
Points: 1,945, Visits: 3,121
would you care to share a definition of the difference of the two?


You'll be sorry; this is the short version

In 25 words or less it is "Logical versus Physical", but it goes beyond that. If you do not have a good conceptual model, you hit a ceiling and cannot get past a certain level of competency.

A file is made up of records, records are made up of fields. Files are independent of each other, while tables in a database are interrelated. You open an entire database, not tables; you open individual files. The original idea of a database was to collect data in a way that avoided redundant data in too many files and not have it dependent on a particular programming language.

A file is ordered and can be accessed by a PHYSICAL location, while a table is not. "first record", "last record", and "next n records" make sense in a file but not in a table. Rows have no magical "id" or "row_id' like the physical record number in a file.

In fact, columns, rows and tables do not have to have any physical existence at all. VIEWs, derived tables and CTEs are virtual tables, I can have computed columns, e5tc.

Look at how many times we get a posting where someone wants to sequentially read a table. In a procedural language, "READ a,b,c FROM FileX;" does not give the same results as "READ b,c,a FROM FileX;" and some languages will let you write "READ a,a,a FROM FileX;"

A file is usually associated with a particular language -- ever try to read a FORTRAN file with a COBOL program? A database is language independent; the internal SQL datatypes are converted into host language data types.

A field exists only because of the program reading it; a column exists because it is in a table in a database. A field is fixed or variable length, can repeated with an OCCURS in COBOL, etc. It does not have to be a scalar value like a column. A field can change datatypes (union in 'C', VARIANT in Pascal, REDEFINES in COBOL); a column cannot. You have no idea whatsoever how a column is represented internally; you never see it. SQL is more abstract than a file system; you think of a number as a NUMBER, and not as a physical string of numerals. you think of a date as a DATE, and not as a physical string of numerals and local punctuation marks.

I wish that more programmers had worked with a magnetic tape system. It is based on physical contiguous storage for everything. This is where the idea of a primary key came from. Everything in a tape system depends the files being sorted on the same key, so you can merge data. It was awhile before Dr. Codd changed his mind and said that all keys are keys, and we don't need a special one in a relational database, like you did in a tape system.

Dr. Codd defined a row as a representation of a fact. A record is usually a combination of a lot of facts. That is, we don't normalize a file; you stuff data into it and hope that you have everything you need for an application.

Rows and columns have constraints. Records and fields can have anything in them and often do!! Talk to anyone who has tried to build a data warehouse about that ...

The other "un-learning" that I see when I teach an SQL class is with people who learned spreadsheets. They think that tables are made of rows and columns; no, tables are made of rows and rows are made of columns. Columns hold scalar values, not pointers or formulas.


Books in Celko Series for Morgan-Kaufmann Publishing
Analytics and OLAP in SQL
Data and Databases: Concepts in Practice
Data, Measurements and Standards in SQL
SQL for Smarties
SQL Programming Style
SQL Puzzles and Answers
Thinking in Sets
Trees and Hierarchies in SQL
Post #1605264
Posted Tuesday, August 19, 2014 10:19 PM
SSCrazy

SSCrazySSCrazySSCrazySSCrazySSCrazySSCrazySSCrazySSCrazy

Group: General Forum Members
Last Login: Today @ 12:59 AM
Points: 2,417, Visits: 6,692
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