Results 1 to 10 of 10
  1. #1
    djay1991 is offline Novice
    Windows 10 Access 2013 32bit
    Join Date
    Apr 2016
    Posts
    5

    Combine tables, many rows to one box

    I have a report I'm trying to build. I have information from two tables that I need to combine. The first is "Service Calls" the second is "Parts Used" on the service during the service call. I want to make each call one line with all the parts in a single box. Using a custom function I found I have been able to do this the only problem is that I get "Error 3075: Syntax error (missing Operator)" when there is no related data in my "Parts Used" table. After going through all the errors the end result is what I want. Is there a way to stop this? Is there a better way to get what I want? I've been working on the for a couple weeks now and am no closer to a solution then when I started.

    Query:
    SELECT DISTINCT [Service Calls].ID, [Service Calls].Equipment_ID, [Service Calls].Notes, ConcatRelated("[Stores_Number]","Parts_Used", "[WO_ID] = " & [WO_ID],"[Stores_Number]",", ") AS All_Parts
    FROM [Service Calls] LEFT JOIN Parts_Used ON [Service Calls].ID = Parts_Used.WO_ID;

    Custom Function (http://allenbrowne.com/func-concat.html):
    Public Function ConcatRelated(strField As String, _
    strTable As String, _
    Optional strWhere As String, _
    Optional strOrderBy As String, _
    Optional strSeparator = ", ") As Variant
    On Error GoTo Err_Handler
    'Purpose: Generate a concatenated string of related records.
    'Return: String variant, or Null if no matches.
    'Arguments: strField = name of field to get results from and concatenate.
    ' strTable = name of a table or query.
    ' strWhere = WHERE clause to choose the right values.
    ' strOrderBy = ORDER BY clause, for sorting the values.
    ' strSeparator = characters to use between the concatenated values.
    'Notes: 1. Use square brackets around field/table names with spaces or odd characters.
    ' 2. strField can be a Multi-valued field (A2007 and later), but strOrderBy cannot.
    ' 3. Nulls are omitted, zero-length strings (ZLSs) are returned as ZLSs.
    ' 4. Returning more than 255 characters to a recordset triggers this Access bug:
    ' http://allenbrowne.com/bug-16.html

    Dim rs As DAO.Recordset 'Related records
    Dim rsMV As DAO.Recordset 'Multi-valued field recordset
    Dim strSql As String 'SQL statement
    Dim strOut As String 'Output string to concatenate to.
    Dim lngLen As Long 'Length of string.
    Dim bIsMultiValue As Boolean 'Flag if strField is a multi-valued field.

    'Initialize to Null
    ConcatRelated = Null

    'Build SQL string, and get the records.
    strSql = "SELECT " & strField & " FROM " & strTable
    If strWhere <> vbNullString Then
    strSql = strSql & " WHERE " & strWhere
    End If
    If strOrderBy <> vbNullString Then
    strSql = strSql & " ORDER BY " & strOrderBy
    End If
    Set rs = DBEngine(0)(0).OpenRecordset(strSql, dbOpenDynaset)
    'Determine if the requested field is multi-valued (Type is above 100.)
    bIsMultiValue = (rs(0).Type > 100)

    'Loop through the matching records
    Do While Not rs.EOF
    If bIsMultiValue Then
    'For multi-valued field, loop through the values
    Set rsMV = rs(0).Value
    Do While Not rsMV.EOF
    If Not IsNull(rsMV(0)) Then
    strOut = strOut & rsMV(0) & strSeparator
    End If
    rsMV.MoveNext
    Loop
    Set rsMV = Nothing
    ElseIf Not IsNull(rs(0)) Then
    strOut = strOut & rs(0) & strSeparator
    End If
    rs.MoveNext


    Loop
    rs.Close

    'Return the string without the trailing separator.
    lngLen = Len(strOut) - Len(strSeparator)
    If lngLen > 0 Then
    ConcatRelated = Left(strOut, lngLen)
    End If

    Exit_Handler:
    'Clean up
    Set rsMV = Nothing
    Set rs = Nothing
    Exit Function

    Err_Handler:
    MsgBox "Error " & Err.Number & ": " & Err.Description, vbExclamation, "ConcatRelated()"
    Resume Exit_Handler
    End Function

  2. #2
    Micron is offline Virtually Inert Person
    Windows 7 32bit Access 2007
    Join Date
    Jun 2014
    Location
    Ontario, Canada
    Posts
    12,803
    You're actually using this without substituting the variables with your names (e.g. strSql = "SELECT " & strField & " FROM " & strTable) as instructed?
    The more we hear silence, the more we begin to think about our value in this universe.
    Paraphrase of Professor Brian Cox.

  3. #3
    djay1991 is offline Novice
    Windows 10 Access 2013 32bit
    Join Date
    Apr 2016
    Posts
    5
    Yes I am. It returns all the data that I want. The only time I get a problem is when there is no corresponding data in my parts used table. The report will eventually be filtered by date, but it should make no difference right now. The images are my results and my error. Entries are only created in my Parts Used table when I actually use a part and each part creates a new entry with WO_ID as my key. Otherwise there will be no corresponding data.
    Click image for larger version. 

Name:	Query results.PNG 
Views:	13 
Size:	23.8 KB 
ID:	24352

    Click image for larger version. 

Name:	error.PNG 
Views:	13 
Size:	8.3 KB 
ID:	24353

  4. #4
    Micron is offline Virtually Inert Person
    Windows 7 32bit Access 2007
    Join Date
    Jun 2014
    Location
    Ontario, Canada
    Posts
    12,803
    I don't see how since the author says to replace strTable with the name of your table, but what you posted doesn't reflect that.
    strTable = name of a table or query.
    OK, so if you say it works most of the time, then I suspect the issue is either you're using an INNER join (which requires the joined fields to have data in both tables and be equal) or the syntax of the sql statement is incorrect when the id is missing in one table. One possibility is to try an OUTER join. Another is to use the NZ function to provide a default value if there is a NULL on wo id. However, without being able to see your table structure, relationships, sql statement, joins, etc. I'm just guessing on what to modify. You can get the Missing Operator message if part of the WHERE clause just ends in a quote because the data is missing.
    edit: possible also that a UNION query is required.

  5. #5
    djay1991 is offline Novice
    Windows 10 Access 2013 32bit
    Join Date
    Apr 2016
    Posts
    5
    I guess I should have said something before but this is my first Access project. I have a little experience with SQL. Haven't done anything with VB since I took a class in 2001 for VB 4.0. If I could accomplish my goal without using the custom function I'm more than willing to change things. So my base problem is
    I have two tables with a left join
    My first table is called Service_Calls
    My second table is called Parts_Ordered
    Only some Service_Calls entries will have corresponding data in Parts_Used
    I use the Service_Call ID as my key
    I need all information on the Service_Calls table filtered by date
    If there are corresponding entries in Parts_Used I need all the Stores_Number to then be concatenated into one text box

    Tell me what you need me to upload.
    I'm hoping to get past this and learn more. Even with getting stuck it's been quite enjoyable learning.
    Thank you

  6. #6
    CJ_London is offline VIP
    Windows 10 Access 2010 32bit
    Join Date
    Mar 2015
    Posts
    11,430
    looks to me like you have identified the issue (you cannot pass a null as criteria), just not handled it

    SELECT DISTINCT ....., iif(isnull([WO_ID]),"",ConcatRelated("[Stores_Number]","Parts_Used", "[WO_ID] = " & [WO_ID],"[Stores_Number]",", ")) AS All_Parts...............

  7. #7
    djay1991 is offline Novice
    Windows 10 Access 2013 32bit
    Join Date
    Apr 2016
    Posts
    5
    Thanks Ajax works perfect. I had a feeling it was an issue that the proper use of isnull or Nz would would fix I just didn't know how to apply it.

  8. #8
    Micron is offline Virtually Inert Person
    Windows 7 32bit Access 2007
    Join Date
    Jun 2014
    Location
    Ontario, Canada
    Posts
    12,803
    I'm curious about something else. Your first post says you want to make a report and asks there's a better way to get what you want. If what you want in fact, is a report, then why are you concatenating all these values in one place as opposed to grouping the parts under a work order or equipment (I don't know which is more appropriate for your purposes) in a report? I must admit I did not try to digest all of the posted code because I didn't see how it was necessary given the power of a report to deal with the no-parts issued work orders, so I'm left wondering why all this code is necessary when you can concatenate in a query field e.g.
    Concat: [Location] & ";" & [Dte] & ";" & [Measurement]
    or, as I said, let the report do the work. I think this is one of those times I should have asked "what is the goal and what have you tried"?

    Tell me what you need me to upload.
    If you ever need to, you can upload a zipped copy of a db for analysis.

  9. #9
    djay1991 is offline Novice
    Windows 10 Access 2013 32bit
    Join Date
    Apr 2016
    Posts
    5
    Micron
    The problem has been with concatenating rows not columns. Every site I've been to so far points me to custom functions. With the Isnull it's now working perfectly.

  10. #10
    Micron is offline Virtually Inert Person
    Windows 7 32bit Access 2007
    Join Date
    Jun 2014
    Location
    Ontario, Canada
    Posts
    12,803
    Thanks. I shoulda figured that out. It was after midnight after all...

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

Similar Threads

  1. Query to combine some rows and leave others.
    By douglas.fagerstrom in forum Queries
    Replies: 13
    Last Post: 06-08-2015, 07:31 PM
  2. Virtually combine two rows for dropdown
    By squirrly in forum Queries
    Replies: 3
    Last Post: 01-28-2013, 03:22 PM
  3. Combine Two Rows - SQL Query
    By Somnath_IT2006 in forum Queries
    Replies: 1
    Last Post: 12-23-2011, 06:30 AM
  4. combine rows
    By summerAIS in forum Queries
    Replies: 3
    Last Post: 07-31-2010, 10:13 PM
  5. Combine multiple rows into one cell
    By zarfx4 in forum Queries
    Replies: 8
    Last Post: 06-08-2009, 10:42 AM

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