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


Best way to insert a lot of data in a database


Best way to insert a lot of data in a database

Author
Message
franck.maton
franck.maton
SSC Rookie
SSC Rookie (39 reputation)SSC Rookie (39 reputation)SSC Rookie (39 reputation)SSC Rookie (39 reputation)SSC Rookie (39 reputation)SSC Rookie (39 reputation)SSC Rookie (39 reputation)SSC Rookie (39 reputation)

Group: General Forum Members
Points: 39 Visits: 344
Hello,

I've generated one file per table of my database. Each file contains 'insert' statement for each records of the table. (did that for data migration purposes with bad collation, blablabla)

I first tried to use SQLCMD to load data into my tables but, apparently, if my file is too big (or there are too many inserts to do) it doesn't work.

I got that error, for big files/tables:
Shared Memory Provider: No process is on the other end of the pipe. Sqlcmd: Error: Microsoft SQL Server Native Client 10.0 : Communication link failure.


Well, I read that "bcp" was THE tool to perform what I want to do. Okay, I gave it a try...

But I've problems with its syntax. I get many errors. Some of these are:

SQLState = 22003, NativeError = 0
Error = [Microsoft][SQL Server Native Client 10.0]Numeric value out of range

[/quote]

and

[quote]SQLState = S1000, NativeError = 0
Error = [Microsoft][SQL Server Native Client 10.0]Unable to open BCP host data-file


What my input file looks like:
INSERT CCE_DATAFILESIZES(ID_DFSIZE,CHECK_DATE,DATABASE_NAME,TABLESPACE_NAME,DATAFILE_NAME,COSTCENTRE,MIN_MB,MAX_MB,AVG_MB,SHARED_DATABASE) 
VALUES('1',convert(datetime,'Apr 27 2012 12:00AM'),'master','PRIMARY','G:\SYS_DB\HSICTR2D\MSSQL10_50.HSICTR2D\MSSQL\DATA\master.mdf','','4.000','0.000','0','n')
INSERT CCE_DATAFILESIZES(ID_DFSIZE,CHECK_DATE,DATABASE_NAME,TABLESPACE_NAME,DATAFILE_NAME,COSTCENTRE,MIN_MB,MAX_MB,AVG_MB,SHARED_DATABASE)
VALUES('2',convert(datetime,'Apr 27 2012 12:00AM'),'master','LOG','G:\SYS_DB\HSICTR2D\MSSQL10_50.HSICTR2D\MSSQL\DATA\mastlog.ldf','','1.000','0.000','0','n')



So, what is the best way to insert a lot of data into tables and how to do it+syntax ?

Here's how i wrote my bcp command:
bcp mydb.dbo.mytable in G:\DATA_DB\Migration\mytable.sql -S server\instance -T -b10000 -c


Please help me, i'm becoming crazy using bcp Crazy

Thanks in advance.
Regards.
Franck.
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: 14957 Visits: 38958
bulk insert expects raw data, and not formatted INSERT...statements.


if your file looked like this isntead:

1,Apr 27 2012 12:00AM
2,Apr 27 2012 12:00AM



bulk insert would insert into a two column table witht eh columns of type INT,datetime increadibly fast.
I've imported much wider files, for example a zip plus 4 database, where the text file was over a gig in size in under 15 minutes;

files with 100K rows of data in under a second are the norm.

here's a simple example, where i use bcp out to send a table to disk, and then bcp or BULK INSERT in the same data to a different table:

because I'm expecting CrLf in note and description fields, I like to use very odd delimiters that I'm sure will not exist in the same data.


--using a super special 4 char row delimiter to be sure it doesn't exist in the data
--flags explanation:
-- -c = character data
-- -t"[||]" = field terminator
-- -r"[~~]" = row terminator
-- -T' = Trusted connection
--out
EXECUTE master.dbo.xp_cmdshell 'bcp "SELECT EMAILTEMPLATESID, EMAILBODY FROM SandBox.dbo.EMAILTEMPLATES ORDER BY EMAILTEMPLATESID" queryout c:\Data\bcpExample.txt -c -t"[||]" -r"[~~]" -T'
--in
EXECUTE master.dbo.xp_cmdshell 'bcp Production.dbo.EMAILTEMPLATES in c:\Data\bcpExample.txt -c -t"[||]" -r"[~~]" -T'
--in via bulk insert
BULK INSERT EMAILTEMPLATES FROM 'c:\Data\bcpExample.txt'
WITH (
DATAFILETYPE = 'char',
FIELDTERMINATOR = '[||]',
ROWTERMINATOR = '[~~]',
FIRSTROW = 1
)



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!

franck.maton
franck.maton
SSC Rookie
SSC Rookie (39 reputation)SSC Rookie (39 reputation)SSC Rookie (39 reputation)SSC Rookie (39 reputation)SSC Rookie (39 reputation)SSC Rookie (39 reputation)SSC Rookie (39 reputation)SSC Rookie (39 reputation)

Group: General Forum Members
Points: 39 Visits: 344
Hahaha, I spent hours on exporting my data and prepare inserts Hehe

Well, thanks for your fast reply, i'll try your way and post my feedback ;-)

Franck
franck.maton
franck.maton
SSC Rookie
SSC Rookie (39 reputation)SSC Rookie (39 reputation)SSC Rookie (39 reputation)SSC Rookie (39 reputation)SSC Rookie (39 reputation)SSC Rookie (39 reputation)SSC Rookie (39 reputation)SSC Rookie (39 reputation)

Group: General Forum Members
Points: 39 Visits: 344
Lowell,

Thank you very much for your help. I still have some issues but it somehow works :-)

Have a nice day.
Franck.
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: 14957 Visits: 38958
let us know if we can help with the additional issues you are encountering; glad i could get you pointed in a helpful direction.

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!

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