Results 1 to 5 of 5
  1. #1
    CamtheChamp is offline Novice
    Windows XP Access 2007
    Join Date
    May 2012
    Posts
    5

    Run code for every record in report

    Hi,

    I am still very new to Access so there may be a better way to do this all together. I was given a poorly designed Access database and I am trying to not have to recreate the entire thing.

    I have a report where I need to create a textbox for each record that displays information based on the value of certain fields. It changes for each record so I need it to run for each record.

    My code:

    Code:
    Private Sub DisplayFrameTypes()
    Dim FrameTypeText As String
    Dim engCMID As String
    Dim SQL As String
    Dim MyRec As ADODB.Recordset
    engCMID = Me.txtEngineeringCostModelID
    SQL = "SELECT qryfrmFrameTypeList.EngineeringCostModelID, qryfrmFrameTypeList.FrameType1, qryfrmFrameTypeList.FrameType2, qryfrmFrameTypeList.FrameType3, qryfrmFrameTypeList.FrameType4, qryfrmFrameTypeList.FrameType5, qryfrmFrameTypeList.FrameType6, qryfrmFrameTypeList.FrameType7, qryfrmFrameTypeList.FrameType8, qryfrmFrameTypeList.FrameType9, qryfrmFrameTypeList.FrameType10, qryfrmFrameTypeList.FrameType11 " & _
    "FROM qryfrmFrameTypeList " & _
    "WHERE qryfrmFrameTypeList.EngineeringCostModelID =" & engCMID & ""
    
    Set MyRec = New ADODB.Recordset
    MyRec.Open SQL, CurrentProject.Connection
    If MyRec("FrameType1") = -1 Then FrameTypeText = "SGen6-Aux" & vbCrLf
    If MyRec("FrameType2") = -1 Then FrameTypeText = FrameTypeText & "SGT6-2000E" & vbCrLf
    If MyRec("FrameType3") = -1 Then FrameTypeText = FrameTypeText & "SGT6-5000F4" & vbCrLf
    If MyRec("FrameType4") = -1 Then FrameTypeText = FrameTypeText & "SGT6-5000F5" & vbCrLf
    If MyRec("FrameType5") = -1 Then FrameTypeText = FrameTypeText & "SGT6-5000F6" & vbCrLf
    If MyRec("FrameType6") = -1 Then FrameTypeText = FrameTypeText & "SGT6-8000H" & vbCrLf
    If MyRec("FrameType7") = -1 Then FrameTypeText = FrameTypeText & "SGT6-8000H(SS)" & vbCrLf
    If MyRec("FrameType8") = -1 Then FrameTypeText = FrameTypeText & "SST6-1000A(104-50)" & vbCrLf
    If MyRec("FrameType9") = -1 Then FrameTypeText = FrameTypeText & "SST6-1000A(104-55)" & vbCrLf
    If MyRec("FrameType10") = -1 Then FrameTypeText = FrameTypeText & "SST6-2000H(110-46)" & vbCrLf
    If MyRec("FrameType11") = -1 Then FrameTypeText = FrameTypeText & "SST6-PAC" & vbCrLf
    Me.Text28.Value = FrameTypeText
    
    End Sub
    The code works fine when I call the function in Private Sub Text28_Click() for a specific record that I click. But I need it to work for each record as soon as the report is created.



    Any ideas on where I should be calling this function or if I should be going in a totally different direction?

    Thanks for your help!

  2. #2
    CamtheChamp is offline Novice
    Windows XP Access 2007
    Join Date
    May 2012
    Posts
    5
    I believe I just figured out the Detail_Print event does what I need. I am still not sure why it worked though.

  3. #3
    ssanfu is offline Master of Nothing
    Windows 2K Access 2000
    Join Date
    Sep 2010
    Location
    Anchorage, Alaska, USA
    Posts
    9,664
    I have a report where I need to create a textbox for each record that displays information based on the value of certain fields
    I am thoroughly confused.
    Are you really "creating" a textbox on the report or updating the value?

    ------------------------------------------
    First, a couple of corrections. You have:
    Code:
    Dim engCMID As String
    
    engCMID = Me.txtEngineeringCostModelID
    
    "WHERE qryfrmFrameTypeList.EngineeringCostModelID =" & engCMID & ""
    You declare engCMID as a string, but in the WHERE clause, you do not have text delimiters for engCMID. I think "engCMID" is a number (probably a Long) and Access is doing a conversion from a string to a number. So the lines should look like:
    Code:
    Dim engCMID As Long
    
    engCMID = Me.txtEngineeringCostModelID
    
    "WHERE qryfrmFrameTypeList.EngineeringCostModelID =" & engCMID
    ------------------------------------------
    Value is the default property, so you can save typing and use

    Me.Text28 = , instead of Me.Text28.Value =

    ------------------------------------------
    You opened the recordset, but didn't close it. You should have

    MyRec.Close

    to close the recordset.

    ------------------------------------------
    What is the record source for the report? If it is a query, I think I would change your code into a function and call it in the query.
    The function could be:
    Code:
    Function FrameType(FT1 As Boolean, FT2 As Boolean, FT3 As Boolean, FT4 As Boolean, FT5 As Boolean, FT6 As Boolean, FT7 As Boolean, FT8 As Boolean, FT9 As Boolean, FT10 As Boolean, FT11 As Boolean) As String
    
       FrameType = ""
    
       If FT1 Then FrameTypeText = "SGen6-Aux" & vbCrLf
       If FT2 Then FrameTypeText = FrameTypeText & "SGT6-2000E" & vbCrLf
       If FT3 Then FrameTypeText = FrameTypeText & "SGT6-5000F4" & vbCrLf
       If FT4 Then FrameTypeText = FrameTypeText & "SGT6-5000F5" & vbCrLf
       If FT5 Then FrameTypeText = FrameTypeText & "SGT6-5000F6" & vbCrLf
       If FT6 Then FrameTypeText = FrameTypeText & "SGT6-8000H" & vbCrLf
       If FT7 Then FrameTypeText = FrameTypeText & "SGT6-8000H(SS)" & vbCrLf
       If FT8 Then FrameTypeText = FrameTypeText & "SST6-1000A(104-50)" & vbCrLf
       If FT9 Then FrameTypeText = FrameTypeText & "SST6-1000A(104-55)" & vbCrLf
       If FT10 Then FrameTypeText = FrameTypeText & "SST6-2000H(110-46)" & vbCrLf
       If FT11 Then FrameTypeText = FrameTypeText & "SST6-PAC" & vbCrLf
    
       'Return
       FrameType = FrameTypeText
    
    End Function
    To use it in the query, the column would look something like:
    Code:
    SELECT qryfrmFrameTypeList.EngineeringCostModelID, qryfrmFrameTypeList.FrameType1, qryfrmFrameTypeList.FrameType2, qryfrmFrameTypeList.FrameType3, qryfrmFrameTypeList.FrameType4, qryfrmFrameTypeList.FrameType5, qryfrmFrameTypeList.FrameType6, qryfrmFrameTypeList.FrameType7, qryfrmFrameTypeList.FrameType8, qryfrmFrameTypeList.FrameType9, qryfrmFrameTypeList.FrameType10, qryfrmFrameTypeList.FrameType11, 
    FT_Text:FrameType(FrameType1, FrameType1, FrameType3, FrameType4, FrameType5 , FrameType6 , FrameType7 , FrameType8 , FrameType9,  FrameType10,  FrameType11)
    
    FROM qryfrmFrameTypeList

  4. #4
    CamtheChamp is offline Novice
    Windows XP Access 2007
    Join Date
    May 2012
    Posts
    5
    Awesome, thanks for the suggestions. What is the importance of doing MyRec.Close?

    I haven't gotten into writing code for Queries yet, so I guess I will try that next.

  5. #5
    ssanfu is offline Master of Nothing
    Windows 2K Access 2000
    Join Date
    Sep 2010
    Location
    Anchorage, Alaska, USA
    Posts
    9,664
    If you don't close the recordset (something you opened), it can lead to memory leaks - you eventually run out of memory (RAM).

    It's not code for queries, but you can use a function to do calculations that couldn't be done in a column in a query. You can do simple things like

    FullName: FName & " " & LName

    to create a full name. But if you want do a calculation like your example or something more complicated, write a function...

Please reply to this thread with any new information or opinions.

Similar Threads

  1. Add record using VBA code
    By nick.h in forum Programming
    Replies: 9
    Last Post: 12-20-2011, 01:17 PM
  2. execute code on subform without adding a record
    By markjkubicki in forum Forms
    Replies: 5
    Last Post: 10-13-2011, 12:23 PM
  3. Replies: 2
    Last Post: 01-27-2011, 08:04 AM
  4. Code to pull in data from a specific record
    By jdunn36 in forum Access
    Replies: 1
    Last Post: 09-20-2010, 11:54 AM
  5. Replies: 4
    Last Post: 05-12-2009, 01:50 PM

Posting Permissions

  • You may not post new threads
  • You may not post replies
  • You may not post attachments
  • You may not edit your posts
  •  
Other Forums: Microsoft Office Forums