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
 

Some videos you may like

Excel Facts

Copy formula down without changing references
If you have =SUM(F2:F49) in F50; type Alt+' in F51 to copy =SUM(F2:F49) to F51, leaving the formula in edit mode. Change SUM to COUNT.

Richard Schollar

MrExcel MVP
Joined
Apr 19, 2005
Messages
23,707
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
 

NBVC

Well-known Member
Joined
Aug 31, 2005
Messages
5,828
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"
 

Richard Schollar

MrExcel MVP
Joined
Apr 19, 2005
Messages
23,707
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
 

NBVC

Well-known Member
Joined
Aug 31, 2005
Messages
5,828
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.
 

Watch MrExcel Video

Forum statistics

Threads
1,109,348
Messages
5,528,182
Members
409,807
Latest member
nicky736

This Week's Hot Topics

  • Change military grades into rank
    Afternoon all Need help with formula that will change military rank (i.e. 1, 2, 3 into Amn, A1C, SrA). Running IF formula that does not work...
  • VBA COUNTIF SOLUTION
    Hi The following are the errors spread across the several columns from E to Q ie. 13 columns across several sheets with more than 500 rows per...
  • INSERT ROW WITH SPECIFIS TEXT IN A COLUMN
    Hi All! How can identify that that the row to be inserted has to be inserted before 1st row with specific text in column F. If I record the...
  • Auto-Create a monthly Sign in sheet for preschool students
    The image below is what each page looks like. Above is space for the "Child Name" "Month" "Class" School days are obviously Monday-Friday but...
  • VBA vlookup multiple results
    Hi folks, Hopefully someone out there can help. I have a list to vlookup which works (ish). the lookup only picks up the first instance of the...
  • Extract values for earliest/latest times
    I am trying to put together a formula to get the earliest start time, the latest end time from column A for each person in Column B-F without the...
Top