Bulk insert statement cannto open file on the share

  • I am trying to execute a bulk insert statement in SQL management studio.

    BULK

    INSERT PSStudentAccess

    FROM '\\servername\pj_sharepoint\external\autosend\myfile.txt"

    WITH

    (

    FIELDTERMINATOR = ',',

    ROWTERMINATOR = ''

    )

    Cannot bulk load because the file "\\servername\pj_sharepoint\external\autosend\myfile.txt" could not be opened. Operating system error code 5(Access is denied.).".

    We have checked this:

    Firstly, the user me already have bulkadmin rights, actually I am sysadmin of the server.

    Secondly, the share has correct permissions for me to access it.

    I also tried to use a local file it works. and a mapped drive point to above UNC path, it works too.

    But just not the shared path like above.

    What could be wrong?

    Thanks,

  • pure permissions is the issue;

    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, or even Bill Gates Secret Superman Login, SQL DOES NOT USE YOUR CREDENTIALS to touch stuff outside of SQL server.

    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.

    [/quote]

    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,

    Is it the same thing comparing what you said:

    http://thesqldude.com/2011/12/30/how-to-sql-server-bulk-insert-with-constrained-delegation-access-is-denied/

    Thanks,

  • Lowell,

    I tried to setup a proxy account, but still same error. Also our SQL server service account is already a domain account and has access to the share. but still no luck.

    from the server event viewer security audit where the shared file locate I can say the attemped log in is anonymous

    Subject:

    Security ID:NULL SID

    Account Name:-

    Account Domain:-

    Logon ID:0x0

    Logon Type:3

    New Logon:

    Security ID:ANONYMOUS LOGON

    Account Name:ANONYMOUS LOGON

    Account Domain:NT AUTHORITY

    Logon ID:0xa1a27fb

    Logon GUID:{00000000-0000-0000-0000-000000000000}

    Process Information:

    Process ID:0x0

    Process Name:-

    With that being said, I suspect this is related with what is mentioned in the above link.

    something related with delegation. but I am not good at that, sounds more like network admin configuration, but just want to know if that is the right direction.

    Thanks

  • i beleive delegation is not involved at all;

    if xp_cmdshell is enabled, you can run this and see who the user is, as wella s wehtehr the user ahs access to teh share.

    modify to uinclude your actual path to the share:

    DECLARE @Results table(

    ID int identity(1,1) NOT NULL,

    TheOutput varchar(1000))

    insert into @Results (TheOutput)

    exec master..xp_cmdshell 'whoami' --nt authority\system for example

    insert into @Results (TheOutput)

    exec master..xp_cmdshell 'cd %userprofile%' --NULL is typical if nt authority\system , since that is not a user...command fails.

    insert into @Results (TheOutput)

    exec master..xp_cmdshell 'dir "\\servername\pj_sharepoint\external\*.*" /b'

    select * from @Results

    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!

  • I run the above script in managment studio on the sql server, its result is

    1mydomain\mysqlsvs --This is my sql server service ccount

    2NULL

    3NULL

    4myfile.txt

    5NULL

    So this means it does have access to the file, correct?

  • yeah i tlooks like the account has read access to the share for sure.

    is there any chance an application has the file open, so the bulk insert process cannot open and read it? getting error 5 /access denied is wierd...i'd expect an error stating opened exclusively or somethign like that.

    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,

    I checked there is no one else open the file, I even rename it to a different to try it,

    It still got the same error.

    So since I searched online a few places talked about delegation thing, it may be that?

    I hope not either, for we never had this issue before.

    But this is first time we use bulk insert and to access shared drive, feel frustrated we have to use delegation for this.

  • I'm going a bit crazy with this too, especially since we have virtually the same setup on a SQL2005 setup and it works fine.

    SQL SERVER is running on a domain account that has full access to the target shares.

    when logged into SQL server under the SQL account, I can open the target files in Windows explorer/notepad

    If I try to run the bulk insert from management studio on my machine even as sysadmin I get the access denied (5) error.

    If I try to run the bulk insert from the SQL server I also get that error.

    ...

    -- FORTRAN manual for Xerox Computers --

  • More info:

    I duplicated the target structure on the SQL server

    On the SQL server I can run the insert if I specify local letter drives.

    However if I point to those same folders (on this machine) using the server name I get the access denied code 5.

    ...

    -- FORTRAN manual for Xerox Computers --

  • Here is what we found:

    Found out if it runs on the server itself, it will run.

    Not run from client to SQL Server then to share. It losts the credential and causing double hop.

    We have below options to try instead:

    Option 1, do not manually run, but just login to server itself to run it, for double hop issue.

    SSIS package will run if it has permissions to the share.

    Option 2: copy the file from networkshare to local SQL server.

    Option 3: map the drive,

    Option 4: use SSIS data flow instead of Bulk insert

    Thanks,

  • Lowell (6/30/2014)


    pure permissions is the issue;

    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, or even Bill Gates Secret Superman Login, SQL DOES NOT USE YOUR CREDENTIALS to touch stuff outside of SQL server.

    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.

    [/quote]

    Good stuff, Lowell. You should submit this as a "Spackle" article so we can all point to it for this very common question.

    --Jeff Moden


    RBAR is pronounced "ree-bar" and is a "Modenism" for Row-By-Agonizing-Row.
    First step towards the paradigm shift of writing Set Based code:
    ________Stop thinking about what you want to do to a ROW... think, instead, of what you want to do to a COLUMN.

    Change is inevitable... Change for the better is not.


    Helpful Links:
    How to post code problems
    How to Post Performance Problems
    Create a Tally Function (fnTally)

  • Thanks for the your suggestions.

    I am still having a real issue with this (error code 5 access denied) and it does not seem to make sense.

    1) SQL server is running on a network account and this network account has explicit permissions on the files.

    2) Proxy account is blank and unchecked.

    3) If I log onto SQL server with that network account I can open the files in notepad etc.

    ..Here's where it gets strange.

    I copied the text files to the SQL server ( to eliminate 'double hop' issues). Since they are small and not a lot of traffic, we can tolerate them on the SQL server.

    I still get the error if I use UNC, however if I use letter drive to the very same files, I can bulk load (unfortunately I will need to use UNC in the actual application)

    I thought perhaps there is a typo in the UNC, so while logged into the SQL server instance of studio, under that same account, I cut and pasted it into 'open text file' and the file opened fine. Hence the UNC is correct.

    arrghhhh!

    ...

    -- FORTRAN manual for Xerox Computers --

  • For everyone's edification and entertainment.

    When a problem makes no sense whatsoever, it's usually more than one problem hiding there.

    The most 'interesting' problem was that the server with the files was one of several VMs that were moved. Somehow in that process the clocks got knocked way out of whack, so certain types of attempted file operations failed to authenticate. (Apparently the domain controller was not pleased)

    Secondly that did hide a bit of a second hop problem, I still had trouble with the remote access using an AD account. However by using an SQL login it seems to have reduced the hop count and things work. (Changing the AD accounts for delegation would involve getting a corporate policy exception, so this is the easier way.)

    ...

    -- FORTRAN manual for Xerox Computers --

  • I am having the same issue. I have checked for my SQL service account, it has access to the fileshare and also enabled for delegation after its SPN was set. Funny part is user can do the bulk insert using the SQL authentication login but the same fails when Windows authenticated login. When I try to run the query locally from the SQL server it runs fine but it fails when I am remotely connecting to the SQL server from my terminal serer using SSMS. Appreciate any help. I am all out of ideas here. 🙁

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

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