[mso] Re: Access VBA SQL

  • From: "Ray Blake" <ray@xxxxxxxxx>
  • To: <mso@xxxxxxxxxxxxx>
  • Date: Tue, 14 Oct 2003 18:45:07 +0100

James,

I actually did this in a different way. My existing query was quite
complex with all sorts of joins that seemed to cause problems when I
tried to create them programmatically. Eventually, I decided there must
be a way to use the good SQL that was already powering the query
definitions and just give it some new criteria.

With a reference to the DAO library, I used the code below to:

1. Get the QueryDef object for the named query
2. Copy its SQL property into a string
3. Crop the string to remove the existing criteria
4. Build a new criteria string that starts with "WHERE"
5. Add this back onto the string
6. Replace the SQL property with the reconstructed string

Clunky, but it seems to be doing the trick!


Dim fullString As String, critString As String, buildString As String
Dim QD As QueryDef
Set QD = CurrentDb.QueryDefs("qryFormExperiment")

fullString = QD.SQL
fullString = Left(fullString, InStr(1, fullString, "WHERE") - 3)
'
' need error trapping for string with no WHERE!
'
FirstFlag = False
critString = ""
' filter accreditation
If Forms(frmFilters).FilterAccred = True Then
    For Each selItem In Forms(frmFilters).ListAccred.ItemsSelected
        critString = critString & " OR 'tblAuthorisation!" &
Forms(frmFilters).ListAccred.ItemData(selItem) & "'=true"
    Next selItem
    FirstFlag = True
    critString = Right(critString, Len(critString) - 4)
    critString = "WHERE (" & critString & ")"
End If


'filter qualification
If Forms(frmFilters).FilterQual = True Then
    If FirstFlag = False Then
        critString = "WHERE "
    Else: critString = critString + " AND "
    End If
    critString = critString & "tblQual!Qualification IN("
    buildString = ""
    For Each selItem In Forms(frmFilters).ListQual.ItemsSelected
        buildString = buildString & ",'" &
Forms(frmFilters).ListQual.ItemData(selItem) & "'"
    Next selItem
    FirstFlag = True
    buildString = Right(buildString, Len(buildString) - 1)
    critString = critString & buildString & ")"
End If

'
' more filters here!
'

fullString = fullString & vbCrLf & critString
QD.SQL = fullString

Ray
_____________

This email is from Ray Blake, Head of Software Design, GR Business
Process Solutions. It is confidential and intended for the addressee
only. The contents are private and may be legally privileged. If you
receive this email in error we would be grateful if you would advise the
sender and delete the email from your system.

For more information on the services that we offer please visit us at
our website: - www.grbps.com 


-----Original Message-----
From: mso-bounce@xxxxxxxxxxxxx [mailto:mso-bounce@xxxxxxxxxxxxx] On
Behalf Of James LaBorde
Sent: 13 October 2003 18:00
To: 'mso@xxxxxxxxxxxxx'
Subject: [mso] Re: Access VBA SQL :VSMail mx2

Ray,

Not sure of how it would be used in the Excel sense of the word but
since
you are using VBA, you can open the querydef if you have it in Access
and
modify it.  If the fields are always the same but have different
criteria,
you can write the querydef on the fly. 

Here is what I would do:

Dim strSQLRoot as string
Dim strSQLWhere as String
Dim strSQL as String
Dim QD as querydef
Set QD

strSQLRoot = Enter your query here without the where.

strSQLWhere = Create your where clause on the fly

strSQL = strSQLRoot & strSQLWhere

qd = strSQL


This will dynamically change your query from your code.

This is a very rudimentary look at it, if you want more detail just let
me
know and I will gladly work with you on it.

James



*************************************************************
You are receiving this mail because you subscribed to mso@xxxxxxxxxxxxx or 
MicrosoftOffice@xxxxxxxxxxxxxxxx

To send mail to the group, simply address it to mso@xxxxxxxxxxxxx

To Unsubscribe from this group, send an email to 
mso-request@xxxxxxxxxxxxx with the word "unsubscribe" (without the quotes) in 
the subject line.

Or, visit the group's homepage and use the dropdown menu.  This will also allow 
you to change your email settings to digest or vacation (no mail).
//www.freelists.org/webpage/mso

To be able to use the files section for sharing files with the group, send a 
request to mso-moderators@xxxxxxxxxxxxx and you will be sent an invitation with 
instructions.  Once you are a member of the files group, you can go here to 
upload/download files:
http://www.smartgroups.com/vault/msofiles
*************************************************************

Other related posts: