SQL Clone
SQLServerCentral is supported by Redgate
 
Log in  ::  Register  ::  Not logged in
 
 
 


Field headers with BCP


Field headers with BCP

Author
Message
BobNEPA
BobNEPA
SSC Journeyman
SSC Journeyman (83 reputation)SSC Journeyman (83 reputation)SSC Journeyman (83 reputation)SSC Journeyman (83 reputation)SSC Journeyman (83 reputation)SSC Journeyman (83 reputation)SSC Journeyman (83 reputation)SSC Journeyman (83 reputation)

Group: General Forum Members
Points: 83 Visits: 10
I have been using BCP to get an extract from our data for a vendor. They now would like field headers on the extract to ensure they are putting the data in the correct fields. Is there any way to do this with BCP or can you suggest another way of getting them the data which is pipe delimited? thanks in advance.....
hardikssit1
hardikssit1
Mr or Mrs. 500
Mr or Mrs. 500 (592 reputation)Mr or Mrs. 500 (592 reputation)Mr or Mrs. 500 (592 reputation)Mr or Mrs. 500 (592 reputation)Mr or Mrs. 500 (592 reputation)Mr or Mrs. 500 (592 reputation)Mr or Mrs. 500 (592 reputation)Mr or Mrs. 500 (592 reputation)

Group: General Forum Members
Points: 592 Visits: 42
I have the same problem as above please reply if any IDEA...
Lowell
Lowell
SSC Guru
SSC Guru (71K reputation)SSC Guru (71K reputation)SSC Guru (71K reputation)SSC Guru (71K reputation)SSC Guru (71K reputation)SSC Guru (71K reputation)SSC Guru (71K reputation)SSC Guru (71K reputation)

Group: General Forum Members
Points: 71230 Visits: 40930
before i discovered CLR functionalities,
i've done this by doing a normal old BCP that pipe delimits mydata like this:

EXECUTE master.dbo.xp_cmdshell
'bcp "SELECT object_name(object_id) As TbLName,name as ColName FROM SandBox.sys.columns ORDER BY object_name(object_id), column_id" queryout C:\Data\Objects.txt -t"|" -c -T '



then using command line funcitonalities, I can create seperate files
that contain whatever headers i want...then i simply append the files together.

dim @sql varchar(8000)
--Create the Header file
SET @sql = 'ECHO "MyHeader File Created ' + CONVERT(VARCHAR(35),getdate(),109) + '" > C:\Data\MyHeader.txt'
EXEC master..xp_cmdshell @sql
--append more data to teh header file
SET @sql = 'ECHO "Additional Header Info Like RowCoutns or something" >> C:\Data\MyHeader.txt'
EXEC master..xp_cmdshell @sql


set @sql ='copy c:\MyHeader.txt + c:\Objects.txt c:\Data\MyFinalFileName.txt'
EXEC master..xp_cmdshell @sql



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!
mayank1979
mayank1979
Forum Newbie
Forum Newbie (1 reputation)Forum Newbie (1 reputation)Forum Newbie (1 reputation)Forum Newbie (1 reputation)Forum Newbie (1 reputation)Forum Newbie (1 reputation)Forum Newbie (1 reputation)Forum Newbie (1 reputation)

Group: General Forum Members
Points: 1 Visits: 2
Dear All,

I have figure out a solution for this please replace db name. This is an SP which will pull table with headers using bcp.

Please suggest me for improvements and interested to see if other options are available.

Regards
Mayank Mehta

IF OBJECT_ID('ExportTableData') IS NOT NULL
DROP PROCEDURE ExportTableData
GO
/****************************************************************************
Procedure Name : ExportTableData
Objective : get all repords of a table
Author : Mayank Mehta
Create Date : 21st AUG 2012
Modified By :
Modified Date :
Input Parameters :

Output parameters:
--
Algorithm and other details:


Test Cases:
DECLARE @result INTEGER
EXEC @result = ExportTableData 'TITAN-163\SQLEXPRESS' , 'Settings_Customer', 'E:\Settings_Customer'
SELECT @result

*****************************************************************************/
CREATE PROCEDURE ExportTableData
(
@serverName VARCHAR(50),
@tableName VARCHAR(20),
@exportLocation VARCHAR(20)
)
AS
BEGIN

--$Header: $
SET NOCOUNT ON

BEGIN TRY

--------------------------------------------------------
--1. Create temp table to store data across Db switch --
--------------------------------------------------------
CREATE TABLE ##tableColumns
(
ColumnName VARCHAR(60),
ColumnID INT,
)

----------------------------
--2. variable declaration --
----------------------------
DECLARE @SQL VARCHAR(8000),
@column VARCHAR(MAX),
@iD INTEGER,
@colCount INTEGER,
@columnSQL VARCHAR(MAX),
@tableColumnString VARCHAR(MAX),
@finalSQL VARCHAR(8000)

SET @iD = 1


---------------------------------------------------
--2. List all colums of required table to export --
---------------------------------------------------
INSERT INTO ##tableColumns
SELECT COLUMN_NAME, Ordinal_Position from information_schema.columns where table_name = @tableName

-------------------------------------
--3. get table count for loooping --
-------------------------------------
SELECT @colCount = COUNT(ColumnID)
FROM ##tableColumns

SELECT @tableColumnString = ''

--------------------------------------
--4. Convet table values in varchar --
--------------------------------------
SELECT @tableColumnString = @tableColumnString + 'CONVERT(VARCHAR,'+ ColumnName + '),'
FROM ##tableColumns

--------------------------------
--5. Remove comma from select --
--------------------------------
SELECT @tableColumnString = LEFT(@tableColumnString, LEN(@tableColumnString) -1)

--------------------------------
--6. prepare select statement --
--------------------------------
SELECT @tableColumnString = ' SELECT ' + @tableColumnString + ' FROM [dbname].dbo.' + @tableName

SELECT @columnSQL = 'Select '

--------------------------------------
--7. loop through to pivite columns --
--------------------------------------
WHILE (@iD <= @colCount)
BEGIN
IF(@iD != @colCount)
BEGIN
SET @columnSQL = @columnSQL + ' COL'+ CONVERT(VARCHAR,@iD) + ' = MAX(CASE WHEN ColumnID = ' + CONVERT(VARCHAR,@iD) + ' THEN ColumnName ELSE NULL END),'
END
ELSE
BEGIN
SET @columnSQL = @columnSQL + ' COL'+ CONVERT(VARCHAR,@iD) + ' = MAX(CASE WHEN ColumnID = ' + CONVERT(VARCHAR,@iD) + ' THEN ColumnName ELSE NULL END)'
END

SET @iD = @iD + 1
END

----------------------------------
--8. Prepare column table query --
----------------------------------
SELECT @columnSQL = @columnSQL + ' FROM ##tableColumns '

-----------------------------------------
--9. Configure xpcmdshall if not exists--
-----------------------------------------
-- To allow advanced options to be changed.
EXEC sp_configure 'show advanced options', '1'

-- To update the currently configured value for advanced options.
RECONFIGURE

-- To enable the feature.
EXEC sp_configure 'xp_cmdshell', '1'

-- To update the currently configured value for this feature.
RECONFIGURE

--------------------
--10. perform BCP --
--------------------
SELECT @SQL = 'bcp "' + @columnSQL + ' Union ALL ' + @tableColumnString + ' " queryout "' + @exportLocation + '.csv' + '" -c -b 20000 -T -S ' + @serverName


EXEC master..xp_cmdshell @SQL

------------------------
--11. Drop temp table --
------------------------
DROP TABLE ##tableColumns

RETURN 0

END TRY
BEGIN CATCH

SELECT @@error

SELECT ERROR_MESSAGE() AS ErrorMessage;
DROP TABLE ##tableColumns

RETURN -1

END CATCH
END
GO
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