Using Input Boxes for Database Query - VBA

NBVC

Well-known Member
Joined
Aug 31, 2005
Messages
5,828
Hello all,

I am trying to use VBA to automate a query to my ERP database system.

This first code is successfull at doing that but it requires the database, user id and password to be part of the macro. The macro will be used by many so I tried to set those variables through use of input boxes. See second code below. It accepts the inputs, but does not retrieve the data.

Can anyone see what may be causing this problem?

It looks like it is trying to use the actual variable names instead of the assigned strings. How do I get it to reference the assigned database, user id, password, instead of the actual variable names?


Code:
Sub GetAllQueries1()

    With ActiveSheet.QueryTables.Add(Connection:=Array(Array( _
        "ODBC;DSN=SANDBOX_ODBC;UID=NBVC;Pwd=ABC;DBQ=SANDBOX;DBA=W;APA=T;EXC=F;FEN=T;QTO=T;FRC=10;FDL=10;LOB=T;RST=T;GDE=F;FRL=F;BAM=IfAllSuccess" _
        ), Array("ful;MTS=F;MDI=F;CSR=F;FWC=F;PFC=10;TLO=0;")), Destination:=Range( _
        "A1"))
        .CommandText = Array( _
        "SELECT PART.ID, PART.FABRICATED" & Chr(13) & "" & Chr(10) & "FROM SYSADM.PART PART" & Chr(13) & "" & Chr(10) & "WHERE (PART.FABRICATED='Y') AND (PART.QTY_ON_HAND>100)" _
        )
        .Name = "Query from SANDBOX_ODBC"
        .FieldNames = True
        .RowNumbers = False
        .FillAdjacentFormulas = False
        .PreserveFormatting = True
        .RefreshOnFileOpen = False
        .BackgroundQuery = True
        .RefreshStyle = xlInsertDeleteCells
        .SavePassword = False
        .SaveData = True
        .AdjustColumnWidth = True
        .RefreshPeriod = 0
        .PreserveColumnInfo = True
        .Refresh BackgroundQuery:=False
    End With
End Sub



Code:
Sub GetAllQueries()

Dim User As Variant, Password As Variant, database As Variant

database = InputBox("Database?", "Database")
ODBC = database & "_ODBC"
User = InputBox("User ID?", "UserId")
Password = InputBox("Password", "Password")



    With ActiveSheet.QueryTables.Add(Connection:=Array(Array( _
        "ODBC;DSN=ODBC;UID=user;Pwd=password;DBQ=database ;DBA=W;APA=T;EXC=F;FEN=T;QTO=T;FRC=10;FDL=10;LOB=T;RST=T;GDE=F;FRL=F;BAM=IfAllSuccess" _
        ), Array("ful;MTS=F;MDI=F;CSR=F;FWC=F;PFC=10;TLO=0;")), Destination:=Range( _
        "A1"))
        .CommandText = Array( _
        "SELECT PART.ID, PART.FABRICATED" & Chr(13) & "" & Chr(10) & "FROM SYSADM.PART PART" & Chr(13) & "" & Chr(10) & "WHERE (PART.FABRICATED='Y') AND (PART.QTY_ON_HAND>100)" _
        )
        .Name = "Query from" & ODBC
        .FieldNames = True
        .RowNumbers = False
        .FillAdjacentFormulas = False
        .PreserveFormatting = True
        .RefreshOnFileOpen = False
        .BackgroundQuery = True
        .RefreshStyle = xlInsertDeleteCells
        .SavePassword = False
        .SaveData = True
        .AdjustColumnWidth = True
        .RefreshPeriod = 0
        .PreserveColumnInfo = True
        .Refresh BackgroundQuery:=False
    End With
End Sub
 

Excel Facts

Workdays for a market open Mon, Wed, Friday?
Yes! Use "0101011" for the weekend argument in NETWORKDAYS.INTL or WORKDAY.INTL. The 7 digits start on Monday. 1 means it is a weekend.
Hi NBVC

You've included your variables in the connection string as string literals, rather than as variables, so the compiler doesn't know that it should be replacing the variables with their values.

Instead of:

Code:
...code snippet...
"ODBC;DSN=ODBC;UID=user;Pwd=password;DBQ=database ;
...

try:

Code:
"...code snippet...
ODBC;DSN=" & ODBC & ";UID=" & user & ";Pwd=" & password & ";DBQ=" & database & ";...

Make sense?

Richard
 
Upvote 0
Hi Richard,

That's Exellent! It worked great! Thank you very much.

I kinda' understand what you mean, but I don't fully grasp why it is defined as such:
Code:
UID=" & user & "
How is that transforming a literal into a variable? Why couldn't it just be:
Code:
UID = "user"
 
Upvote 0
When the compiler 'reads' your code, everything surrounded by the double quotes it treats as text. Thus, to get the compiler to recognise that it is seeing a variable and not text, we have to place it outside of the double quotes. But, we want whatever value the variable holds to be incorporated within the string we are building (ie the connection string), so we use the concatenation operator & to incorporate it. It's rather like the following Excel worksheet function:

If you have a name in cell A1 (say "Richard") and want B1 to return a message saying "Hello Richard - how do you do?", you wouldn't write it like:

Code:
="Hello "A1" - How do you do?"

you'd build it like:

Code:
="Hello " & A1 & " - How do you do?"

Hope this makes it clearer!

Richard
 
Upvote 0
Oh yes, I see....I didn't realize the first quotes was in front of ODBC at the start of the string: :oops:

Code:
"ODBC;DSN=" & ODBC & ";UID=" & User & ";Pwd="....

I should have looked at like this:
Code:
"ODBC;DSN=" & variable & ";UID=" & variable...etc...
just like in Excel. It's just that first quote threw me off that is why I was offsetting the strings and seeing it like this.
Code:
UID=" & user & "

Thanks for setting me straight Richard.
 
Upvote 0

Forum statistics

Threads
1,214,375
Messages
6,119,164
Members
448,870
Latest member
max_pedreira

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