BCP Utility to output contents into CSV

  • I have a stored procedure that gets a SQL query, file path (to output) and file name as parameter which I'm using to build a bcp command and finally executing the same e.g

    SET @sql = 'bcp "'

    + @query

    + '" queryout "

    + @path_nm

    + @file_nm

    + '" -c'

    + ' -t,'

    + ' -T'

    EXECUTE MASTER..xp_cmdshell @sql, NO_OUTPUT

    Upon executing the stored proc it doesn't produce the file specified in the parameter.

    I have verified the parameters and they are correct. I did a print to see what's in @sql and say I get the following -

    'bcp "SELECT [col1],[col2],[col3] FROM [##results]" queryout "E:\test\test.csv" -c -t, -T'

    On executing the command standalone (i.e. not from a stored proc) from SSMS produces the output file correctly e.g.

    EXEC MASTER..xp_cmdshell 'bcp "SELECT [col1],[col2],[col3] FROM [##results]" queryout "E:\test\test.csv" -c -t, -T', NO_OUTPUT

    Confused!

    Are there any limitations on running BCP utility from a stored proc - am I missing something very obvious?

    Please help!

    Thanks, Bikram

  • I would check permissions. Doesthe SQL Server service account have permissions to the e:\test drive? It likely doesn't by default.

  • Hi Steve,

    I thought about that and I had checked the permission - seems fine (SQL Server users have special permission to create files / append data etc). Also I would have thought if permission was an issue then the result would be same when running from SSMS just by itself. What is confusing me is the difference in result between running from a Stored Procedure and running the same by itself as mentioned in my post earlier.

    As a sysadmin on the server - should permission be an issue for sysadmin?

    Thanks,

    Bikram

  • bikram.g.it (5/21/2013)


    I thought about that and I had checked the permission. I would have thought if permission was an issue then the result would be same when running from SSMS just by itself. What is confusing me is the difference in result between running from a Stored Procedure and running the same by itself as mentioned in my post earlier.

    my guess is that the calling user ends up using the proxy account that might be set up, whereas a sysadmin user, when going to xp_cmdshell, always uses the context of the startup account.

    do something like this to test it yourself:

    EXECUTE AS USER='Bob'

    EXECUTE MyProcedure @MyParameters

    --note the error message

    REVERT; --change back to sysadmin

    The proxy account for normal users, if it is set up:

    The startup account, which is used if the proxy is blank, or the user is a sysadmin

    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!

  • Lowell has the potential issue. A proxy could do this for sure.

    Other than that, I'd still guess it's some weird permissions thing. You could to a

    xp_cmdshell "dir > myfile.txt"

    and then see where myfile.txt ends up, if it does. Working through different commands might help you track things down if it's not the proxy.

  • Lowell / Steve,

    Some good thoughts - the proxy account I had setup is using the admin user. So that should be fine I guess.

    I tried the dir test e.g. EXEC MASTER..xp_cmdshell 'dir E:\test\*.*> E:\test\myfile_1.txt', NO_OUTPUT

    this runs perfectly fine both from a SSMS session and from a stored proc.

    I guess it is probably something to with BCP Utility fired off a stored proc. But not entirely sure!

  • Could you add the fully qualified path name for the bcp executable, and an explict server with -S and try it again? And just as a long shot, you're not also connecting to Sybase from this machine are you? Also, adding the -e option to write to an error file might provide additional diagnostic info.


    And then again, I might be wrong ...
    David Webb

  • Hi David,

    We are no where near Sybase. -S / server option I have already tried but I guess it doesn't make much difference as the whole deal is on the same server. Re fully qualified path for BCP executable - tried this now and same result. Tried the -e option as well no error out created so I guess no errors in processing the command - not entirely sure if -e works for queryout; think it is only for IN operation (may be wrong).

    Thanks,

    Bikram

  • Can you set a login trigger and look for the login from BCP to the instance? I wonder if there's some issue connecting back from BCP.

    Can you dir the path you have in the command to a file with xp_cmdshell? Ensure that's correct. Also, can you perhaps hard code the BCP command that you run in SSMS in the proc and see what happens?

  • OK - so I modified the stored proc a bit to have something like this -

    EXECUTE @RESULT = MASTER..xp_cmdshell 'bcp "SELECT COL1, COL2 FROM [##results]" queryout "E:\test\TEST1.csv" -c -t, -T -S DWETLSERV1 -oE:\test\BCPCMD_1.txt', NO_OUTPUT

    EXEC MASTER..xp_cmdshell 'dir "C:\Program Files\Microsoft SQL Server\90\Tools\binn\*.exe"> E:\test\myfile_1.txt', NO_OUTPUT

    EXECUTE @RESULT = MASTER..xp_cmdshell @sql_1, NO_OUTPUT

    @sql contains bcp "SELECT COL1, COL2 FROM [##results]" queryout "E:\test\TEST2.csv" -c -t, -T -S DWETLSERV1 -oE:\test\BCPCMD_2.txt

    I got TEST1.csv, BCPCMD_1.txt & myfile_1.txt where TEST1.csv contains the result of the SQL query BCPCMD_1.txt contains the output of the first BCP command and myfile_1.txt contains all the exe files in the location mentioned (including bcp) and I have checked the path as well that has the location set as well.

    But I didn't get TEST2.csv & BCPCMD_2.txt.

    Seems xp_cmdshell is getting trouble running @sql!

  • Hi Guys,

    Thanks for all your suggestions.

    I have spotted the problem - it is nothing to do with the permission, bcp, cmdshell, sybase (or anything as thought about ......)

    What it turns out to be is @sql contains LF \ CR and xp_cmdshell doesn't want to troop along with this.....:w00t::angry::crazy:

    However surprisingly when passed the same query directly into xp_cmdshell it worked fine.

    So for the purpose of the topic is not resolved. But I will carry on in this voyage of discovery as to why it is so fussy about the specials chars in @sql unless you guys already know it!

  • Thanks for the update. I'm not sure I would have thought of that, but a great catch.

    Did you use some type of hex editor to find this?

  • Cheers! I just wanted to format the ugly looking SQL in @sql while someone was watching over my shoulder and then I had a light bulb moment - that it could be a possibility that BCP / cmdshell is having trouble having those LFs...... and there was the result.

  • Wouldn't you have to do something like:

    EXECUTE @RESULT = 'MASTER..xp_cmdshell '+ @sql +'_1, NO_OUTPUT'

    or

    SET @RESULT = EXECUTE MASTER..xp_cmdshell [sql]_1, NO_OUTPUT

    set @result = replace(@result, '[sql]', '@sql')

    exec @result

  • This is what has worked for me. This code is embedded in a S/P and runs on a schedule and gives me a CSV like clockwork every night. Needs no tweaking of permissions or access, other than turning xp_cmdshell ON and OFF. In addition, bcp is itself used to fire a S/P, not just a static query. Note that the stored procedure name can also be parameterized and works fine. I just leave in plain text for maintainability.

    --turn xp_cmdshell ON as I leave them off by default:

    EXECUTE master.dbo.sp_configure 'show advanced options', 1

    RECONFIGURE

    EXEC master.dbo.sp_configure 'xp_cmdshell', 1

    RECONFIGURE

    SET @sql = 'bcp "exec [WorkflowV3].[dbo].aStatusExtractDataCSV" queryout "' + @destFolder + @fileName + '" -t \, -T -c'

    EXECUTE master.dbo.xp_cmdshell @sql

    --and then turn xp_cmdshell back OFF for security's sake

    EXEC master.dbo.sp_configure 'xp_cmdshell', 0

    RECONFIGURE

    EXECUTE master.dbo.sp_configure 'show advanced options', 0

    RECONFIGURE

    Good luck!

    Sigerson

    "No pressure, no diamonds." - Thomas Carlyle

Viewing 15 posts - 1 through 15 (of 22 total)

You must be logged in to reply to this topic. Login to reply