master.dbo.xp_cmdshell Error

  • I need to create a stored procedure that would perform an automatic database restore from 1 server to another

    First step in my task is to be able to copy over the .bak file from 1 location to another across different server

    Here is what I have created

    declare @bak_source varchar(255), @bak_dest varchar(255), @xcopycmd varchar(max)

    set @bak_source='\\qa\d$\Full_2010.bak'

    set @bak_dest='\\dev\d$\Data'

    set @xcopycmd=N'xcopy '+ @bak_source +' '+ @bak_dest +''

    select @xcopycmd

    EXEC master.dbo.xp_cmdshell @xcopycmd, NO_OUTPUT

    I get the following error mssg

    Msg 214, Level 16, State 201, Procedure xp_cmdshell, Line 1

    Procedure expects parameter 'command_string' of type 'varchar'.

    Also,

    Since the sp will be performing copying of files, does the login associated to execute this sp need to be a windows admin and a sys admin on sql as well ?

    What kind of access/ account should I create to make it same across all environment to aviod any permissions issue ?

  • don't declare one of the variables as varchar(max); use a defined size instead; no error occurs when you do this:

    declare @bak_source varchar(255), @bak_dest varchar(255), @xcopycmd varchar(1000)

    set @bak_source='"\\qa\d$\Full_2010.bak"'

    set @bak_dest='"\\dev\d$\Data"'

    set @xcopycmd='xcopy '+ @bak_source +' '+ @bak_dest +''

    select @xcopycmd

    EXEC master.dbo.xp_cmdshell @xcopycmd, NO_OUTPUT

    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!

  • Thanks Lowell,

    It executed without any errors but nothing got copied over

  • LOOKUP_BI-756009 (11/2/2010)


    Thanks Lowell,

    It executed without any errors but nothing got copied over

    an important piece of this puzzle is the account the SQL service is running under. Even though YOU are a network admin and have access to those machines, when xp_cmdshell is called, It's THAT account that is calling xp_cmdshell and trying to access those two remote machines.

    instead of no_output, use this to see the results...it can help you track down the issue.

    DECLARE @Results table(

    ID int identity(1,1) NOT NULL,

    TheOutput varchar(1000))

    declare @bak_source varchar(255), @bak_dest varchar(255), @xcopycmd varchar(1000)

    set @bak_source='"\\qa\d$\Full_2010.bak"'

    set @bak_dest='"\\dev\d$\Data"'

    set @xcopycmd='xcopy '+ @bak_source +' '+ @bak_dest +''

    select @xcopycmd

    insert into @Results (TheOutput)

    EXEC master.dbo.xp_cmdshell @xcopycmd

    select * from @Results

    you might need to change the user being used to run the service to one that has access to those shares:

    this is a common security misconception/"gotcha". The problem is that when you access any resource OUTSIDE of SQL server, like network shares, local hard drives and folders,xp_cmdshell,bcp with a "trusted" connection, sp_OA type functions etc.

    it doesn't matter what YOUR credentials are. Whether you are Domain Admin,Local Admin , logged in as sa, administrative login on a laptop, etc, because SQL will not carry those credentials to the "outside of SQL" security context.

    SQL WILL pass your credentials to a linked server, but anything else is using an account you did not intuitively expect it to use.

    SQL Server uses either the account set up as the proxy account, or if that is left blank(the default) it uses account it starts with to try and access the resource:

    or if the above was blank, the account in services:

    That account is often an account which has never logged into the domain, and was never assigned permissions to get to the local disk or network share.

    As a result, you usually need to create a domain account in Active Directory, specifically grant it share access if it doesn't inherit it from Domain\Users or Domain\AuthenticatedUsers and change the account SQL Server starts with to that account.

    Once that is done, and you stop and start the SQL service to make it use that account instead of old running values, your linked server/xp_cmdshell would work.

    you can prove this is the issue by simply putting in your credentials, with your domain account and password, and confirm the external object you were trying to access/use works when SQL is run your credentials, so you'd know you need a domain account to access the resource.

    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!

  • Hi Lowell, Apologies for the late response, I got cought up with some Prod issues.Here is the result from the execution script

    Invalid drive specification

    0 File(s) copied

    NULL

    Here is the current setup for our environment,

    1) All environment [ PROD, DEV, QA...] have different service accounts setup for SQL Server & SQL Server Agent

    2) Some environment have Server properties > Security > Set up proxy account already created

    The xp_cmdshell part to copy the .bak file is a small part of my database automate restore script which would include performing the actual restore, kill active connection and some other task.

    What type of account/security setup would you suggest so that I would be able to copy the.bak file across different environment and execute the sp within a sql job ?

  • Disregard my last post if you saw it. Perhaps if I read your final reply all the way through I would have seen that you already have the service accounts set up. My apologies.

Viewing 6 posts - 1 through 5 (of 5 total)

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