July 18, 2016 at 7:33 pm
I have around 2000 tables i need to export to text files. I tried using the Export Wizard which works if you are doing 1 table at a time. Try to export table in an excel file but i have tables bigger than what Excel can handle. How else can i export several tables to text at once. Thanks
July 18, 2016 at 8:48 pm
Do the tables all have the same columns?
--Jeff Moden
Change is inevitable... Change for the better is not.
July 18, 2016 at 9:21 pm
No, different tables
July 18, 2016 at 9:27 pm
If it were me, I'd write a loop to step through the tables to create a BCP command that did a SELECT * from each table and then use xp_CmdShell to execute it. I recommend using TABs for delimiters.
--Jeff Moden
Change is inevitable... Change for the better is not.
July 18, 2016 at 9:46 pm
Is this close?
-- create a cursor to loop over this result set
/* create a cursor to loop through each table... */
DECLARE @CmdLine AS NVARCHAR(200);
DECLARE @CmdCursor AS CURSOR;
SET @CmdCursor = CURSOR FORWARD_ONLY FOR
SELECT 'bcp ' + '"SELECT * FROM ' +
QUOTENAME(DB_NAME())
+ '.'
+QUOTENAME(SCHEMA_NAME(schema_id))
+ '.'
+QUOTENAME(name)
+ '"'+' queryout'+' '
+ 'c:\' + name + '.csv -c -t, -T -S '
+ @@servername
FROM sys.objects
WHERE TYPE='u'
AND is_ms_shipped=0
AND name <> 'sysdiagrams';
OPEN @CmdCursor;
FETCH NEXT FROM @CmdCursor INTO @CmdLine;
WHILE @@FETCH_STATUS = 0
BEGIN
PRINT @CmdLine;
EXEC xp_CmdShell @CmdLine;
FETCH NEXT FROM @CmdCursor;
END
CLOSE @CmdCursor;
DEALLOCATE @CmdCursor;
July 18, 2016 at 10:52 pm
July 19, 2016 at 12:10 am
pietlinden (7/18/2016)
Is this close?
-- create a cursor to loop over this result set
/* create a cursor to loop through each table... */
DECLARE @CmdLine AS NVARCHAR(200);
DECLARE @CmdCursor AS CURSOR;
SET @CmdCursor = CURSOR FORWARD_ONLY FOR
SELECT 'bcp ' + '"SELECT * FROM ' +
QUOTENAME(DB_NAME())
+ '.'
+QUOTENAME(SCHEMA_NAME(schema_id))
+ '.'
+QUOTENAME(name)
+ '"'+' queryout'+' '
+ 'c:\' + name + '.csv -c -t, -T -S '
+ @@servername
FROM sys.objects
WHERE TYPE='u'
AND is_ms_shipped=0
AND name <> 'sysdiagrams';
OPEN @CmdCursor;
FETCH NEXT FROM @CmdCursor INTO @CmdLine;
WHILE @@FETCH_STATUS = 0
BEGIN
PRINT @CmdLine;
EXEC xp_CmdShell @CmdLine;
FETCH NEXT FROM @CmdCursor;
END
CLOSE @CmdCursor;
DEALLOCATE @CmdCursor;
I believe that nails it.
--Jeff Moden
Change is inevitable... Change for the better is not.
July 19, 2016 at 10:18 am
Thank you for the answers posted. I am a bit new on scripting Cursors so i was wondering how to use a character for field terminator instead of a comma, like "§".
July 19, 2016 at 3:04 pm
gjuarez (7/19/2016)
Thank you for the answers posted. I am a bit new on scripting Cursors so i was wondering how to use a character for field terminator instead of a comma, like "§".
The field terminator has nothing to do with cursors and everything to do with BCP. Please see the following URL and look for the -t argument for how to use it to change the field terminator. I'd do it for you but want to inspire you to use existing documentation because you're the one that needs to support this. 😉
https://msdn.microsoft.com/en-us/library/ms162802(v=sql.120).aspx
--Jeff Moden
Change is inevitable... Change for the better is not.
Viewing 9 posts - 1 through 8 (of 8 total)
You must be logged in to reply to this topic. Login to reply