Results 1 to 6 of 6
  1. #1
    shank is offline Competent Performer
    Windows XP Access 2007
    Join Date
    Sep 2010
    Posts
    188

    Concatenate LineNo

    I've been trying to take advantage of a function created by Allen Browne posted below. I need to concatenate LineNo per each PoNo. I'm aware I will have issues converting a number field into a text result with 3 digits. But I can't seem to get out the gate with an error I understand. I think I'm providing all elements required but getting he below errors. What am I missing?

    Thanks!

    Error 3061: Too few parameters. Expected 1.
    Error 3464: Data type mismatch in criteria expression.

    SELECT DISTINCT
    [PoNo],
    ConcatRelated([Order Import]![LineNo],
    "[Order Import]",
    "[PoNo] = " & [PoNo],
    "[Order Import]![LineNo]",
    "/"
    ) AS LineNo
    FROM [Order Import];



    Table: [Order Imports]
    PoNo - text
    LineNo - number
    PoNo LineNo
    A100 1
    A200 23
    A200 25
    A300 1
    A300 30
    A300 234
    A400 4
    A400 56
    A400 78
    A400 456

    Desired Query Results:
    PoNo LineNo
    A100 001
    A200 023/025
    A300 001/030/234
    A400 004/056/078/456


    Code:
    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
    CJ_London is online now VIP
    Windows 10 Access 2010 32bit
    Join Date
    Mar 2015
    Posts
    11,927
    aware I will have issues converting a number field into a text result with 3 digits
    use the format function

    PONo & "/" & format(LineNo,"000")

    will provide preceding zeros for numbers 0-99

  3. #3
    shank is offline Competent Performer
    Windows XP Access 2007
    Join Date
    Sep 2010
    Posts
    188
    Thanks! That helped my number to text plus zeroes issues.
    But I still get the error:
    Error 3061: Too few parameters. Expected 1.
    I'm guessing I'm not providing enough elements, but not seeing what I'm missing.
    Thoughts?

    SELECT DISTINCT [Order Import].PoNo, ConcatRelated([Order Import]![LineNo],"[Order Import]","[PoNo] = " & [PoNo],Format([Order Import]![LineNo],"000"),"/") AS LineNo
    FROM [Order Import];

  4. #4
    orange's Avatar
    orange is offline Moderator
    Windows 10 Access 2010 32bit
    Join Date
    Sep 2009
    Location
    Ottawa, Ontario, Canada; West Palm Beach FL
    Posts
    16,870
    Try

    Code:
    SELECT DISTINCT [Order Import].PoNo
    , concatrelated("Format(LineNo,'000')","[Order Import]","POno  ='" & [PoNo] & "'","","/") AS ConcatLineNo
    FROM [Order Import];

    PoNo ConcatLineNo
    A100 001
    A200 023/025
    A300 001/030/234
    A400 004/056/078/456

    I have found that if you want to ignore the 4th parameter, and supply a different separator as parameter 5, you have to supply a ZLS for parameter 4 (as shown in the SQL above).

  5. #5
    shank is offline Competent Performer
    Windows XP Access 2007
    Join Date
    Sep 2010
    Posts
    188
    Very much appreciated! This worked:

    SELECT DISTINCT [Order Import].PoNo, ConcatRelated("Format(LineNo,'000')","[Order Import]","PoNo ='" & [PoNo] & "'","","/") AS LineNo
    FROM [Order Import];

  6. #6
    orange's Avatar
    orange is offline Moderator
    Windows 10 Access 2010 32bit
    Join Date
    Sep 2009
    Location
    Ottawa, Ontario, Canada; West Palm Beach FL
    Posts
    16,870

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

Similar Threads

  1. Concatenate
    By Alex Motilal in forum Queries
    Replies: 2
    Last Post: 07-25-2017, 09:44 AM
  2. concatenate a lookup value
    By southpawz505 in forum Access
    Replies: 1
    Last Post: 01-02-2014, 09:10 AM
  3. Concatenate Records
    By Siiig in forum Queries
    Replies: 4
    Last Post: 02-19-2013, 08:17 AM
  4. Replies: 5
    Last Post: 03-13-2012, 01:13 PM
  5. concatenate
    By stephenaa5 in forum Programming
    Replies: 2
    Last Post: 10-11-2010, 05:18 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