Update the hard-coded line

shre0047

Board Regular
Joined
Feb 3, 2017
Messages
53
Office Version
  1. 365
Platform
  1. Windows
I have a VBA to pull data from a database, but I am trying to not hard-code it. I am needing to pull a few tests from the database and currently running it, then changing the code to update the ids.

Currently:
Code:
SQLquery = SQLquery & " Where t.TS_TEST_ID = '39324' OR t.TS_TEST_ID = '39166' OR t.TS_TEST_ID = '12345'

What I want to do is the line is looking at cell values in Sheet1.
Script#139324
Script#239166
Script#312345
Script#432456

<tbody>
</tbody>

I want to extract 20-25 at a time so the table listed above would provide all the scripts. This is what I have so far:
Code:
SQLquery = SQLquery & " AND t.TS_TEST_ID = " & "'" & Sheets("Sheet1").Range("B1").Value & "'" & "
 
Last edited:

Excel Facts

Test for Multiple Conditions in IF?
Use AND(test, test, test, test) or OR(test, test, test, ...) as the logical_test argument of IF.
It is much easier in you take advantage of the IN operator.
See: https://www.w3schools.com/sql/sql_in.asp

So, if we wanted to loop through all the values in column B on Sheet1 to build our list of IDs and build our WHERE condition, it would look something like this:
Code:
    Dim lr As Long
    Dim r As Long
    Dim myList As String
    Dim cond As String
    
'   Find last row in Sheet1, column B
    lr = Sheets("Sheet1").Cells(Rows.Count, "B").End(xlUp).Row
    
'   Loop through all values in column B and make them a list
    For r = 1 To lr
        myList = myList & "'" & Sheets("Sheet1").Cells(r, "B") & "',"
    Next r
    
'   Drop last comma off of myList
    If Len(myList) > 0 Then
        myList = Left(myList, Len(myList) - 1)
'       Build condition
        cond = " WHERE t.TS_TEST_ID IN (" & myList & ")"
'       Return condition for inspection
        MsgBox cond
    End If
 
Upvote 0

Forum statistics

Threads
1,215,329
Messages
6,124,302
Members
449,150
Latest member
NyDarR

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