Click here to monitor SSC
SQLServerCentral is supported by Redgate
 
Log in  ::  Register  ::  Not logged in
 
 
 


OPENROWSET() Intermittently Fails to Read Excel File


OPENROWSET() Intermittently Fails to Read Excel File

Author
Message
Rich Mechaber
Rich Mechaber
Ten Centuries
Ten Centuries (1.1K reputation)Ten Centuries (1.1K reputation)Ten Centuries (1.1K reputation)Ten Centuries (1.1K reputation)Ten Centuries (1.1K reputation)Ten Centuries (1.1K reputation)Ten Centuries (1.1K reputation)Ten Centuries (1.1K reputation)

Group: General Forum Members
Points: 1087 Visits: 3661
I've had this problem a number of times: every so often, I receive errors like this when trying to query an Excel xls file:

OLE DB provider "Microsoft.Jet.OLEDB.4.0" for linked server "(null)" returned message "Could not find installable ISAM.".
Msg 7303, Level 16, State 1, Line 1
Cannot initialize the data source object of OLE DB provider "Microsoft.Jet.OLEDB.4.0" for linked server "(null)".


What I've tried:

1. Ensuring the Excel file is not open. The OPENROWSET() statement is correctly configured, b/c the query works sometimes.

2. Bouncing the SQL service. This always fixes the problem, but doesn't tell me why it happens or when it will recur. And of course, it's a horrible "solution."

3. Checking MDAC. Used the MS consistency checker, and all looked OK.

4. Reading in the file saved in Excel XSLX 2007 format using the Microsoft.ACE.OLEDB.12.0' provider. This game me the following out-of-memory error:
Msg 7399, Level 16, State 1, Line 1
The OLE DB provider "Microsoft.ACE.OLEDB.12.0" for linked server "(null)" reported an error. The provider ran out of memory.
Msg 7320, Level 16, State 2, Line 1
Cannot execute the query "SELECT * FROM [Sheet1$]" against OLE DB provider "Microsoft.ACE.OLEDB.12.0" for linked server "(null)".


5. Tweaking the "MemToLeave" setting with the -g startup switch for the service, as described here: http://www.johnsansom.com/sql-server-memory-configuration-determining-memtoleave-settings/#axzz1SkRKB7Fz. I later ran the query given at his web page and returned the following values of Total avail mem, KB: 23800 and Max free size, Kb: 3444.

UPDATE: After a service restart, I immediately checked and got values of 216056 and 91840 for Total Available Memory, Kb and Max Free Size, Kb, respectively. Again, after a service restart I had no problem running the same OpenRowset() query. I started the service without the "-g" flag, using default values of MemToLeave. BOL (http://msdn.microsoft.com/en-us/library/ms190737%28v=SQL.90%29.aspx) says the default is 256 Mb.

This seems to suggest that there's insufficient RAM for running the OPENROWSET() query, consistent with the out-of-memory error trying to execute the query using the ACE.OLDEDB.12.0 provider for the XSLX file.

So.

I've seen enough blog postings to know that this is a pervasive problem with an often indeterminate solution.

1. Is this a problem caused by insufficient memory for Virtual Address Space?

2. If so, how do I find the cause of the problem?

3. If not, what can I do to fix this so it doesn't recur?

This is a significant problem for me, b/c I'm using OPENROWSET for importing Excel files into SQL. I am reluctant to use SSIS, b/c it's hitting a nail with a sledge hammer.

Any assistance would be welcome.
Rich
SwePeso
SwePeso
SSCrazy
SSCrazy (2.5K reputation)SSCrazy (2.5K reputation)SSCrazy (2.5K reputation)SSCrazy (2.5K reputation)SSCrazy (2.5K reputation)SSCrazy (2.5K reputation)SSCrazy (2.5K reputation)SSCrazy (2.5K reputation)

Group: General Forum Members
Points: 2469 Visits: 3431
Use IMEX=1 in your extended properties for the driver.


N 56°04'39.16"
E 12°55'05.25"
Rich Mechaber
Rich Mechaber
Ten Centuries
Ten Centuries (1.1K reputation)Ten Centuries (1.1K reputation)Ten Centuries (1.1K reputation)Ten Centuries (1.1K reputation)Ten Centuries (1.1K reputation)Ten Centuries (1.1K reputation)Ten Centuries (1.1K reputation)Ten Centuries (1.1K reputation)

Group: General Forum Members
Points: 1087 Visits: 3661
SwePeso (7/22/2011)
Use IMEX=1 in your extended properties for the driver.

Thanks, but that's not the issue here.

The same query on the same Excel file works fine immediately after (and for some varying time after) a service restart.

Likewise, though I didn't include this in my o.p., the issue some have written about re: NTFS permissions in the user temp folder is not germane. I can run the same query on the same spreadsheet without problem after a service restart. So NTFS permissions aren't in play.

Anyone else have an idea?
Rich
dineshvishe
dineshvishe
Valued Member
Valued Member (68 reputation)Valued Member (68 reputation)Valued Member (68 reputation)Valued Member (68 reputation)Valued Member (68 reputation)Valued Member (68 reputation)Valued Member (68 reputation)Valued Member (68 reputation)

Group: General Forum Members
Points: 68 Visits: 342
hi,
I had check following query it is working,

select * from OPENROWSET('Microsoft.Jet.OLEDB.4.0',
'Excel 8.0;Database=c:\Employee.xls;',
'SELECT * FROM [Sheet1$]')

If any problem ,Let me know.

Regards,
Dinesh
sqldriver
sqldriver
Mr or Mrs. 500
Mr or Mrs. 500 (586 reputation)Mr or Mrs. 500 (586 reputation)Mr or Mrs. 500 (586 reputation)Mr or Mrs. 500 (586 reputation)Mr or Mrs. 500 (586 reputation)Mr or Mrs. 500 (586 reputation)Mr or Mrs. 500 (586 reputation)Mr or Mrs. 500 (586 reputation)

Group: General Forum Members
Points: 586 Visits: 2492
rmechaber (7/22/2011)
SwePeso (7/22/2011)
Use IMEX=1 in your extended properties for the driver.

Thanks, but that's not the issue here.

The same query on the same Excel file works fine immediately after (and for some varying time after) a service restart.

Likewise, though I didn't include this in my o.p., the issue some have written about re: NTFS permissions in the user temp folder is not germane. I can run the same query on the same spreadsheet without problem after a service restart. So NTFS permissions aren't in play.

Anyone else have an idea?
Rich


I used to get that pretty often using Jet 4.0, and the only solution anyone ever had was to cycle the service. Recently switched to Ace, and hoping I don't also run into the other error now too. That was half the reason I switched.
Rich Mechaber
Rich Mechaber
Ten Centuries
Ten Centuries (1.1K reputation)Ten Centuries (1.1K reputation)Ten Centuries (1.1K reputation)Ten Centuries (1.1K reputation)Ten Centuries (1.1K reputation)Ten Centuries (1.1K reputation)Ten Centuries (1.1K reputation)Ten Centuries (1.1K reputation)

Group: General Forum Members
Points: 1087 Visits: 3661
Old thread, but in case someone finds this still relevant, I did finally discover the problem and solution.

If you Google memtoleave you will find the answer: SQL 2005 sets aside a separate address space apart from the buffer pool, used for things like OPENROWSET queries. If this becomes fragmented, you will be limited to using the largest contiguous chunk of memory left in it. The only way I'm aware of to reset this separate address space to the unfragmented value is to restart the SQL service, which is why bouncing the service "fixed" the problem.

The solution was to alter the service startup switch that allocates memtoleave memory to a larger value:
http://www.johnsansom.com/sql-server-memory-configuration-determining-memtoleave-settings/
http://sqlblog.com/blogs/jonathan_kehayias/archive/2009/07/07/understanding-the-vas-reservation-aka-memtoleave-in-sql-server.aspx

For SQL 2005, the relevant explanation is here, look for the "-g" startup switch, and increase it as needed. This robs RAM from the buffer pool, so be careful with it.

The article on Kehayias' link, above, includes a query you can run to determine how much VAS is left available, and the largest contiguous chunk left. I put a version of this query on an Agent job and ran it hourly, dumping the results to a logging table, so I could track the pool's depletion.

I think 2008 fixed this, but in case anyone still runs 2005 I figured I'd post this fix.

Rich
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