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

Field headers with BCP Expand / Collapse
Author
Message
Posted Tuesday, June 21, 2011 7:41 AM
Forum Newbie

Forum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum Newbie

Group: General Forum Members
Last Login: Thursday, June 23, 2011 5:44 AM
Points: 5, 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.....
Post #1129001
Posted Tuesday, October 11, 2011 6:43 AM
Mr or Mrs. 500

Mr or Mrs. 500Mr or Mrs. 500Mr or Mrs. 500Mr or Mrs. 500Mr or Mrs. 500Mr or Mrs. 500Mr or Mrs. 500Mr or Mrs. 500

Group: General Forum Members
Last Login: Wednesday, October 30, 2013 12:00 AM
Points: 535, Visits: 42
I have the same problem as above please reply if any IDEA...
Post #1188393
Posted Tuesday, October 11, 2011 7:12 AM


SSChampion

SSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampion

Group: General Forum Members
Last Login: Today @ 6:24 AM
Points: 12,744, Visits: 31,069
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

--There is no spoon, and there's no default ORDER BY in sql server either.
Actually, Common Sense is so rare, it should be considered a Superpower. --my son
Post #1188417
Posted Tuesday, August 21, 2012 8:03 AM
Forum Newbie

Forum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum Newbie

Group: General Forum Members
Last Login: Wednesday, August 22, 2012 2:32 AM
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






Post #1347806
« Prev Topic | Next Topic »

Add to briefcase

Permissions Expand / Collapse