MS Query from Excel database (Excel 2000) Text and Numbers

Makrini

Well-known Member
Joined
May 22, 2007
Messages
1,035
Hi all,

I am trying to find a way to pull a query from an excel list without MS Query assuming the format... I have in 1 column both numbers and text and wish to be able to pull all of that information. (Standard queries either guess the column is text and doesn't bring the numbers or guesses the column is numbers and ignores the text)

I know there is a way of changing the registry to do so, however this would require me to do this on the entire network which our IT department will not hear of.

I am competent in VBA and Excel so if anyone has a workaround in either please let me know...

(My current workaround involves having blank rows in my list which I change to whichever format I want - then do 2 queries and merge in the final file)
 

Excel Facts

How to total the visible cells?
From the first blank cell below a filtered data set, press Alt+=. Instead of SUM, you will get SUBTOTAL(9,)
Hi,

I don't know about a general solution from MS Query. However in the special circumstance that you have text that might be a number - such as '123 or "123" or similar - in which case one easy way is to use something like "* 1" in the SQL. Such as,
Code:
SELECT Field * 1 AS [Field]

Other than MS Query, please refer to ""A Caution about Mixed Data Types" in Microsoft's http://support.microsoft.com/kb/257819
It describes a solution for ADO as setting IMEX=1 in the connection string. I just tested this and it works. I've often encountered this and never had a solution to now. Thanks for prompting me.

Here is the test I ran, late binding the ADO,
Code:
Sub test()

   Dim objConnection As Object
   Dim objRecordset As Object
   Dim strSQL As String

   Set objConnection = CreateObject("ADODB.Connection")
   objConnection.Open Join$(Array("Provider=Microsoft.Jet.OLEDB.4.0; Data Source=", _
      ThisWorkbook.FullName, ";Extended Properties=""Excel 8.0; IMEX=1;"""), vbNullString)
      
   Set objRecordset = CreateObject("ADODB.Recordset")
   
   With objRecordset
      .Open "SELECT * FROM MyTable", objConnection, 3, 2
      ActiveSheet.Range("D2").CopyFromRecordset objRecordset
   End With

   objConnection.Close
   Set objRecordset = Nothing
   Set objConnection = Nothing

End Sub

So, I believe it can't be done with MS Query - but I am happy to be proven wrong - but is simple using ADO.

HTH, Fazza
 
Upvote 0
Thanks for your help - and doesn't matter about MS Query I hate that interface anyway and only use it to help prompt my sql code in VBA.

You have provided a great solution - thanks a lot
 
Upvote 0
You're welcome. Please let me know if you encounter problems with it. I'll do the same if I find anything, as I'll be using it too. Cheers.
 
Upvote 0
Your code is working great for the some of my text/number fields - although I think that some of the columns that start with mostly numbers (I think if the first 10 rows have majority numbers) it assumes those fields are numbers instead.

Is there a way I can force it to view them all as text? Or reduce the number of rows it checks for a majority?

This query is already speeding up the majority of my spreadsheets as well as having the added benefit of keeping the raw data secure from prying hands who like to accidentally change things.
 
Upvote 0
For anyone following this thread - my workaround solution...

in my database excel file..
I put 1 header row...
4 Garbage text rows
4 Garbage number rows

Now I can do query with IMEX=1 and pull all values as text - or do a summary query without IMEX=1 and add up the numbers ignoring the text.
 
Upvote 0

Forum statistics

Threads
1,223,912
Messages
6,175,340
Members
452,637
Latest member
Ezio2866

We've detected that you are using an adblocker.

We have a great community of people providing Excel help here, but the hosting costs are enormous. You can help keep this site running by allowing ads on MrExcel.com.
Allow Ads at MrExcel

Which adblocker are you using?

Disable AdBlock

Follow these easy steps to disable AdBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the icon in the browser’s toolbar.
2)Click on the "Pause on this site" option.
Go back

Disable AdBlock Plus

Follow these easy steps to disable AdBlock Plus

1)Click on the icon in the browser’s toolbar.
2)Click on the toggle to disable it for "mrexcel.com".
Go back

Disable uBlock Origin

Follow these easy steps to disable uBlock Origin

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back

Disable uBlock

Follow these easy steps to disable uBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back
Back
Top