January 28, 2015 at 2:40 pm
Hi
I have this table
CREATE TABLE [Sales].[Test_inmem]
(
[c1] [int] NOT NULL,
[c2] [nvarchar](20) COLLATE SQL_Latin1_General_CP1_CI_AS NOT NULL,
[ModifiedDate] [datetime2](7) NOT NULL CONSTRAINT [IMDF_Test_ModifiedDate] DEFAULT (sysdatetime()),
CONSTRAINT [IMPK_Test_SpecialOfferID_ProductID] PRIMARY KEY NONCLUSTERED
(
[c1] ASC
),
INDEX [ix_Test] NONCLUSTERED
(
[c1] ASC
)
)WITH ( MEMORY_OPTIMIZED = ON , DURABILITY = SCHEMA_AND_DATA )
I have to generate 1000000 random records into it.
I tried various ways to insert records, but not being a developer could not do it.
I hope to make the C1 as a serial number, C2 can be anything, C3 I want to be the timestamp.
Paresh Motiwala Manager of Data Team, Big Data Enthusiast, ex DBA
January 28, 2015 at 4:56 pm
Why not make c1 an identity column?
Otherwise you can use a Tally table. Search on "tally table" and you'll find plenty of ways to do that.
My thought question: Have you ever been told that your query runs too fast?
My advice:
INDEXing a poor-performing query is like putting sugar on cat food. Yeah, it probably tastes better but are you sure you want to eat it?
The path of least resistance can be a slippery slope. Take care that fixing your fixes of fixes doesn't snowball and end up costing you more than fixing the root cause would have in the first place.
Need to UNPIVOT? Why not CROSS APPLY VALUES instead?[/url]
Since random numbers are too important to be left to chance, let's generate some![/url]
Learn to understand recursive CTEs by example.[/url]
[url url=http://www.sqlservercentral.com/articles/St
January 29, 2015 at 8:55 am
making C1 as identity column helped.
Thanks.
Paresh
Paresh Motiwala Manager of Data Team, Big Data Enthusiast, ex DBA
January 29, 2015 at 9:40 am
Paresh Motiwala (1/28/2015)
HiI have this table
CREATE TABLE [Sales].[Test_inmem]
(
[c1] [int] NOT NULL,
[c2] [nvarchar](20) COLLATE SQL_Latin1_General_CP1_CI_AS NOT NULL,
[ModifiedDate] [datetime2](7) NOT NULL CONSTRAINT [IMDF_Test_ModifiedDate] DEFAULT (sysdatetime()),
CONSTRAINT [IMPK_Test_SpecialOfferID_ProductID] PRIMARY KEY NONCLUSTERED
(
[c1] ASC
),
INDEX [ix_Test] NONCLUSTERED
(
[c1] ASC
)
)WITH ( MEMORY_OPTIMIZED = ON , DURABILITY = SCHEMA_AND_DATA )
I have to generate 1000000 random records into it.
I tried various ways to insert records, but not being a developer could not do it.
I hope to make the C1 as a serial number, C2 can be anything, C3 I want to be the timestamp.
Here's my general purpose test table generator. You can pick up how to quickly generate a million "random records" from this code.
--===== Do this in a nice, safe place that everyone has.
USE tempdb
;
--===== Conditionally drop the test table to make reruns easier in SSMS.
IF OBJECT_ID('tempdb.dbo.JBMTest','U') IS NOT NULL
DROP TABLE tempdb.dbo.JBMTest
;
--===== Create a substantial test table with the following columns and values.
-- SomeID = Unique Integers starting at 1 up thru the number of rows generated.
-- SomeDate = Random Integers 1 thru 50,000
-- SomeLetters2 = Random letters "AA" thru "ZZ"
-- SomeDecimal = Random Decimal amounts from 0.00 up to and not including 100,000
-- SomeDate = Random Datetime from 2010-01-01 up to and not including 2020-01-01
-- SomeHex = Random hexidecimal characters with random locations of dashes.
SELECT TOP (1000000)
SomeID = IDENTITY(INT,1,1)
,SomeInt = ABS(CHECKSUM(NEWID()))%50000+1
,SomeLetters2 = CHAR(ABS(CHECKSUM(NEWID()))%26+65)
+ CHAR(ABS(CHECKSUM(NEWID()))%26+65)
,SomeDecimal = CAST(RAND(CHECKSUM(NEWID()))*100000 AS DECIMAL(9,2))
,SomeDate = RAND(CHECKSUM(NEWID()))*DATEDIFF(dd,'2010','2020')+CAST('2010' AS DATETIME)
,SomeHex = SUBSTRING(LEFT(NEWID(),36),ABS(CHECKSUM(NEWID()))%37,ABS(CHECKSUM(NEWID()))%37)
INTO dbo.JBMTest
FROM sys.all_columns t1
CROSS JOIN sys.all_columns t2
;
--===== Add the PK
ALTER TABLE dbo.JBMTest
ADD PRIMARY KEY CLUSTERED (SomeID)
;
If you want to know how that works, please see the following two articles as a starter.
http://www.sqlservercentral.com/articles/Data+Generation/87901/
http://www.sqlservercentral.com/articles/Test+Data/88964/
--Jeff Moden
Change is inevitable... Change for the better is not.
Viewing 4 posts - 1 through 3 (of 3 total)
You must be logged in to reply to this topic. Login to reply
This website stores cookies on your computer.
These cookies are used to improve your website experience and provide more personalized services to you, both on this website and through other media.
To find out more about the cookies we use, see our Privacy Policy