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

Insert dummy records Expand / Collapse
Author
Message
Posted Friday, June 14, 2013 1:09 PM
SSC Veteran

SSC VeteranSSC VeteranSSC VeteranSSC VeteranSSC VeteranSSC VeteranSSC VeteranSSC Veteran

Group: General Forum Members
Last Login: Yesterday @ 4:11 PM
Points: 297, Visits: 1,183
I got asked to do this today, with some generic country data. Here's what I did:

begin tran

declare @id int
set @id = ((select max(id) from table) + 1)
while (@id <= 1002261)
begin
begin
insert into
table (id, country)
values(@id, 'Germany')
end
set @id = @id + 1
end

rollback
commit

So this added 200 additional incremented IDs with country set to Germany. Does anyone else have a trick they use?
Post #1463751
Posted Friday, June 14, 2013 1:27 PM


SSCrazy

SSCrazySSCrazySSCrazySSCrazySSCrazySSCrazySSCrazySSCrazy

Group: General Forum Members
Last Login: Yesterday @ 4:27 PM
Points: 2,763, Visits: 5,899
Something like this?
http://www.sqlservercentral.com/articles/Data+Generation/87901/



Luis C.
I am a great believer in luck, and I find the harder I work the more I have of it. Stephen Leacock

Forum Etiquette: How to post data/code on a forum to get the best help
Post #1463761
Posted Friday, June 14, 2013 1:50 PM
SSC Veteran

SSC VeteranSSC VeteranSSC VeteranSSC VeteranSSC VeteranSSC VeteranSSC VeteranSSC Veteran

Group: General Forum Members
Last Login: Yesterday @ 4:11 PM
Points: 297, Visits: 1,183
Luis Cazares (6/14/2013)
Something like this?
http://www.sqlservercentral.com/articles/Data+Generation/87901/


I'm not totally sure I follow that article, but it didn't seem like IDs were generated in order? My example was just adding 200 rows to an existing table with country populated.

Post #1463763
Posted Friday, June 14, 2013 1:55 PM


SSCrazy

SSCrazySSCrazySSCrazySSCrazySSCrazySSCrazySSCrazySSCrazy

Group: General Forum Members
Last Login: Yesterday @ 4:27 PM
Points: 2,763, Visits: 5,899
So, you basically want to generate IDs with the same value X number of times?
For that, you can check The "Numbers" or "Tally" Table: What it is and how it replaces a loop.



Luis C.
I am a great believer in luck, and I find the harder I work the more I have of it. Stephen Leacock

Forum Etiquette: How to post data/code on a forum to get the best help
Post #1463764
Posted Friday, June 14, 2013 2:14 PM
SSC Veteran

SSC VeteranSSC VeteranSSC VeteranSSC VeteranSSC VeteranSSC VeteranSSC VeteranSSC Veteran

Group: General Forum Members
Last Login: Yesterday @ 4:11 PM
Points: 297, Visits: 1,183
Hm. Is it really necessary, or better, to involve another table? My ID column is PK/Identity, which in my mind at least, seems tallied already, or self-tallying? Something like that. I see the tally table and 8k splitter suggested for a lot of things on here. Maybe it's the small-ish data sets I work with, but I just don't get them. But I don't really get Cross Apply either, no matter how many things I read about it, so maybe I just haven't had the proper experience.

Post #1463766
Posted Friday, June 14, 2013 2:43 PM


SSCrazy

SSCrazySSCrazySSCrazySSCrazySSCrazySSCrazySSCrazySSCrazy

Group: General Forum Members
Last Login: Yesterday @ 4:27 PM
Points: 2,763, Visits: 5,899
Let me give you an example by simplifying your code.

DECLARE @id INT

SELECT @id= max(id) + 1
FROM TABLE

INSERT INTO TABLE (
id
,country
)
SELECT
n
,'Germany'
FROM dbo.Tally
WHERE n BETWEEN @id AND @id <= 1002261


You wouldn't need a cycle or an explicit transaction because it's only one statement. And if the ID is defined as an Identity column, you need even less code.

If you don't like the idea of using a physical table and want everything done on memory, you could create a view for a cteTally with schemabinding as suggested by Sean Lange which I could search for you if you want.

8K Splitter is very common for unnormalized data.

Finally, to understand CROSS/OUTER APPLY, think of it as a JOIN with extended functionality. More info on http://www.sqlservercentral.com/blogs/sqlstudies/2013/05/20/the-many-uses-of-cross-apply/



Luis C.
I am a great believer in luck, and I find the harder I work the more I have of it. Stephen Leacock

Forum Etiquette: How to post data/code on a forum to get the best help
Post #1463770
Posted Friday, June 14, 2013 3:22 PM
SSC Veteran

SSC VeteranSSC VeteranSSC VeteranSSC VeteranSSC VeteranSSC VeteranSSC VeteranSSC Veteran

Group: General Forum Members
Last Login: Yesterday @ 4:11 PM
Points: 297, Visits: 1,183
That is neat. I'll mess with it some this weekend.

Thanks

Post #1463773
Posted Saturday, June 15, 2013 8:23 AM


SSC-Dedicated

SSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-Dedicated

Group: General Forum Members
Last Login: Yesterday @ 5:41 PM
Points: 35,944, Visits: 30,229
To add to Luis' good posts, the Tally Table does have the limit of whatever it contains. Most people make a Tally Table to contain 11,000 or fewer rows. Some make Tally Tables with a million rows but that's still an artificial limit.

If you want something that is only limited by the MAX value of the INT datatype, you might want to try a variation of Itzik Ben-Gan's cCTE (cascading CTE) method for generating sequences of INT's that start at 1. Here's a function to do so. I call the function "Tally1" for two reasons... 1) to keep from interfering with anyone that might have a table named "Tally" already and 2) to let me know that it'll return a sequence starting at "1". I also have functions called "Tally0" and "TallyRange" that do pretty much as they say.

Here's the "Tally1" function.

 CREATE FUNCTION dbo.Tally1
/**********************************************************************************************
Purpose:
Return a sorted column of INTs from 1 to @MaxN.

Usage:
SELECT t.N
FROM dbo.Tally1(@MaxN)

Notes:
1. Based on Itzik Ben-Gan's cascading CTE (cCTE) method for creating a "readless" Tally Table
source of INTs.
2. Has been optimized for use with the INT datatype, therefor the MAX number that can be
returned is actually 2,147,483,647. Larger numbers will return an INT Overflow error.

Revision History:
Rev 00 - 08 Feb 2013 - Jeff Moden - Initial creation
**********************************************************************************************/
(@MaxN INT)
RETURNS TABLE WITH SCHEMABINDING AS
RETURN
WITH
E1(N) AS (SELECT 1 UNION ALL SELECT 1), --2^1 or 2 Rows
E4(N) AS (SELECT 1 FROM E1 a, E1 b, E1 c, E1 d), --2^4 or 16 Rows
E16(N) AS (SELECT 1 FROM E4 a, E4 b, E4 c, E4 d), --2^16 or 65,536 Rows
E32(N) AS (SELECT 1 FROM E16 a, E16 b) --2^32 or 4,294,967,296 Rows
SELECT TOP(@MaxN) N = CAST(ROW_NUMBER() OVER (ORDER BY (SELECT NULL)) AS INT) FROM E32
;

Note that these types of cCTE's are very fast. Almost as fast as having an actual Tally Table. The BIG advantages are 1) they don't have an artificial limit >1 and 2) the produce absolutely "0" reads.

Once you have that function in place (and you should put one in place... they're very useful just like a Tally Table is), then your problem becomes high-performance child's play.

    WITH cteFindMax(MaxID) AS (SELECT MAX(ID) FROM dbo.YourTable)
INSERT INTO dbo.YourTable
(ID, Country)
SELECT ID = m.MaxID + t.N,
Country = 'Germany'
FROM cteFindMax m
CROSS APPLY dbo.Tally(1002261 - m.MaxID)t
;

Shifting gears a bit, if you didn't know what the new MAX was that you wanted to have but knew you wanted to add, say, 100 rows, that's even easier.

 INSERT INTO dbo.YourTable
(ID, Country)
SELECT ID = (SELECT MAX(ID) FROM dbo.YourTable) + t.N,
Country = 'Germany'
FROM dbo.Tally(100)t
;



--Jeff Moden
"RBAR is pronounced "ree-bar" and is a "Modenism" for "Row-By-Agonizing-Row".

First step towards the paradigm shift of writing Set Based code:
Stop thinking about what you want to do to a row... think, instead, of what you want to do to a column."

"Change is inevitable. Change for the better is not." -- 04 August 2013
(play on words) "Just because you CAN do something in T-SQL, doesn't mean you SHOULDN'T." --22 Aug 2013

Helpful Links:
How to post code problems
How to post performance problems
Post #1463853
« Prev Topic | Next Topic »

Add to briefcase

Permissions Expand / Collapse