The sample FROM clause I posted was
FROM [Excel 8.0;HDR=No;database=C:\MyWorkbook.xls;].[Sheet1$A1:E100]
You have
FROM [Excel 9.0,HDR=No,database=C:\Documents and Settings\hargida\My Documents\Access\April.xls,]
Even in Office 2003 (i.e. version 11 of the Office apps) the Excel ISAM
requires "Excel 8.0" (or earlier). Using "Excel 9.0" gives you the
"Cannot find installable ISAM" error. As for using commas instead of
semicolons...
On Thu, 12 May 2005 06:24:04 -0700, Klatuu
Thansk, John. I understand the field naming problems. When I looked at your
example, F1, F2... I confused that as a field name with Excel Cell
designation. Now, the file name problem I don't quite get. why would .xls,
be seen differently than .xls; by Jet? If I use ; as in your example, I get
the message I mentioned earlier. I will give this a try this morning. And,
again, thanks for your help.
:
Your query is specifying field names A4, B4..., but you have specified
HDR=No.
With HDR=No, Jet uses the default field names F1, F2...
With HDR=Yes, the field names in the query must match the contents of
the cells in the first row.
I'm not surprised the , gives a "Not a valid file name error". I reckon
that Jet is reading the filename as "April.xls,", and "xls," is not a
registered extension for the Excel ISAM driver.
On Wed, 11 May 2005 14:41:03 -0700, Klatuu
John,
I tried using the example you posted eariler, but I am getting run time
error 3005 "Not a Valid File Name" error. The file does exist. I had some
other issues, but managed to get through them. If you would please look at
my code and give me any ideas on what might be the problem here.
Notice I changed the ; to , from your example. With the ; the error was run
time 3170 "Could not find installable ISAM"
Sub ImportPipeline()
Dim strSQL As String
strSQL = "INSERT INTO tblPipeline80 ( Curr_Year, Curr_Month, " _
& "Program_Manager, ITM, Opportunity, Resource, Jan, Feb, Mar, " _
& "Apr, May, Jun, Jul, Aug, Sep, Oct, Nov, Dec ) " _
& "SELECT '2005' as Curr_Year, '04' as Curr_Month, A4, B4, C4, D4,
E4, " _
& "F4, G4, H4, I4, J4, K4, L4, M4, N4, O4, P4 " _
& "FROM [Excel 9.0,HDR=No,database=C:\Documents and
Settings\hargida\My Documents\Access\April.xls,]" _
& ".[80%$A4
100];"
CurrentDb.Execute strSQL
End Sub
:
Hi Brad,
You can use an Excel sheet as the source of a SQL append query, e.g.
INSERT INTO TheTable
SELECT F1, F2, F3, F4, F5
FROM [Excel 8.0;HDR=No;database=C:\MyWorkbook.xls;].[Sheet1$A1:E100]
;
As well as a range of cells, the last part of the FROM clause can
specify "all the data on a sheet" ([Sheet1$]) or a named range
([RangeName]). The HDR= argument says whether or not the first row of
the range contains field names.
You can add a WHERE clause or join to limit the records that are
imported, e.g.
INSERT INTO TheTable
SELECT ID, FirstName, LastName
FROM [Excel 8.0;HDR=Yes;database=C:\MyWorkbook.xls;].[Sheet2]
WHERE ID NOT IN (SELECT ID FROM TheTable)
;
(or just rely on your primary key index and other constraints to
prevent import of records that are already in the table).
On Tue, 10 May 2005 12:50:06 -0700, "Brad"
Thanks for taking the time to read my question.
I have a DB that I am currently designing. I will have some data in Excel
that I want to import into a table. The Excel file will contain ALL the
companies available. I only want to import the NEW companies (The ones that
are in the Excel file but not in the DB).
I can do this if I import the Excel to a Temp table, but I am wondering if I
can just open Excel, access the data, run a query or something to find the
new records, import the new records without importing all the data from
Excel. Access will grow too fast and will have to be compacted too often.
My users will not remember to do that.
Does Linking keep the DB size down?
Thanks for the help.
Brad