One to Many Relationships and showing rows as columns (1 Viewer)

Dumferling

Member
Local time
Today, 11:18
Joined
Apr 28, 2020
Messages
102
I have a one to many relationship. One table is Products and the other table is Classifications. Each product has at least one classification but some have two. In a normal query I will link the two tables and get the product information twice and the only difference between the rows will be the different classification. Wlorking in Access this isn't an issue - Sub forms and Sub Reports make this easy.

A Select query looks like this:

Product 1 Classification A
Product 1 Classification B

The problem is that I need to do is export the results of this query to Excel or Word and it doesn't work out. So the solution is to move the Classification to a column rather than a row:

Product 1 Classification A Classification B

Does anyone have any ideas on how to do this? Or if it can be done? It seems to me that it should be possible but I can't see a way to do it.
 

theDBguy

I’m here to help
Staff member
Local time
Today, 02:18
Joined
Oct 29, 2018
Messages
21,501
Have you tried using a crosstab query?
 

arnelgp

..forever waiting... waiting for jellybean!
Local time
Today, 17:18
Joined
May 7, 2009
Messages
19,246
use Allen Browne ConcatRelated() function.
Code:
' USAGE:
' SELECT CompanyName,  ConcatRelated("OrderDate", "tblOrders", "CompanyID = " & [CompanyID])
' FROM tblCompany;
' modified ConcatRelated
' orig by Allen Browne
'
' modified by arnelgp
' for https://www.access-programmers.co.uk/forums/threads/concatrelated-issue.320810/
' add Unique values
'
Public Function ConcatRelated(ByVal strField As String, _
                        ByVal strTable As String, _
                        Optional ByVal strWhere As String = "", _
                        Optional ByVal strOrderBy As String = "", _
                        Optional ByVal strSeparator = ", ", _
                        Optional ByVal bolUniqueValuesOnly As Boolean = False) 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.Recordset2         'Related records
    Dim rsMV As DAO.Recordset2       '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.
   
    'arnelgp
    Dim arrValues() As Variant
    Dim dictValues As Object
    Dim i As Integer
   
    'arnelgp
    'create new dictionary object
    Set dictValues = CreateObject("Scripting.Dictionary")
    'Initialize to Null
    ConcatRelated = Null
    'Build SQL string, and get the records.
   
    If Left$(strTable, 6) = "SELECT" Then
        ' arnelgp
        ' you can pass an SQL string now instead of table/query
        strSql = "SELECT [" & strField & "] FROM (" & strTable & ")"
    Else
        strSql = "SELECT [" & strField & "] FROM " & strTable
    End If
    ' arnelgp
    ' clean SQL string
    strSql = Replace$(strSql, ";", vbNullString)
    strSql = Replace$(strSql, "[[", "[")
    strSql = Replace$(strSql, "]]", "]")
    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
                    ' arnelgp
                    If bolUniqueValuesOnly Then
                        If dictValues.Exists(rsMV(0) & "") = False Then
                            dictValues.Add key:=rsMV(0) & "", Item:=rsMV(0).value
                        End If
                    Else
                        i = i + 1
                        dictValues.Add key:=i & "", Item:=rsMV(0).value
                    End If
                    'strOut = strOut & rsMV(0) & strSeparator
                End If
                rsMV.MoveNext
            Loop
            Set rsMV = Nothing
        ElseIf Not IsNull(rs(0)) Then
            ' arnelgp
            If bolUniqueValuesOnly Then
                If dictValues.Exists(rs(0) & "") = False Then
                    dictValues.Add key:=rs(0) & "", Item:=rs(0).value
                End If
            Else
                i = i + 1
                dictValues.Add key:=i & "", Item:=rs(0).value
            End If
            'strOut = strOut & rs(0) & strSeparator
        End If
        rs.MoveNext
    Loop
    rs.Close
    ' arnelgp
    i = dictValues.count
    If i <> 0 Then
        ReDim arrValues(dictValues.count - 1)
        Dim Items As Variant
        Items = dictValues.Items
        For i = 0 To UBound(Items)
            arrValues(i) = Items(i)
        Next
        ConcatRelated = Join(arrValues, strSeparator)
    End If
   
    '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 dictValues = Nothing
    Erase arrValues
    Set rsMV = Nothing
    Set rs = Nothing
    Exit Function

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

create a Query:

SELECT Product, ConcatRelated("Category","yourTable","Product = '" & [Product] & "'", , " ", False) As Categories
FROM yourTable GROUP BY Product;
 
Last edited:

theDBguy

I’m here to help
Staff member
Local time
Today, 02:18
Joined
Oct 29, 2018
Messages
21,501
Hi

I have but it is not viable - there is too much information in the query
Guess you'll have to use code then. Can you post a sample db with test data?
 

Dumferling

Member
Local time
Today, 11:18
Joined
Apr 28, 2020
Messages
102
use Allen Browne ConcatRelated() function.
Code:
' USAGE:
' SELECT CompanyName,  ConcatRelated("OrderDate", "tblOrders", "CompanyID = " & [CompanyID])
' FROM tblCompany;
' modified ConcatRelated
' orig by Allen Browne
'
' modified by arnelgp
' for https://www.access-programmers.co.uk/forums/threads/concatrelated-issue.320810/
' add Unique values
'
Public Function ConcatRelated(ByVal strField As String, _
                        ByVal strTable As String, _
                        Optional ByVal strWhere As String = "", _
                        Optional ByVal strOrderBy As String = "", _
                        Optional ByVal strSeparator = ", ", _
                        Optional ByVal bolUniqueValuesOnly As Boolean = False) 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.Recordset2         'Related records
    Dim rsMV As DAO.Recordset2       '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.
  
    'arnelgp
    Dim arrValues() As Variant
    Dim dictValues As Object
    Dim i As Integer
  
    'arnelgp
    'create new dictionary object
    Set dictValues = CreateObject("Scripting.Dictionary")
    'Initialize to Null
    ConcatRelated = Null
    'Build SQL string, and get the records.
  
    If Left$(strTable, 6) = "SELECT" Then
        ' arnelgp
        ' you can pass an SQL string now instead of table/query
        strSql = "SELECT [" & strField & "] FROM (" & strTable & ")"
    Else
        strSql = "SELECT [" & strField & "] FROM " & strTable
    End If
    ' arnelgp
    ' clean SQL string
    strSql = Replace$(strSql, ";", vbNullString)
    strSql = Replace$(strSql, "[[", "[")
    strSql = Replace$(strSql, "]]", "]")
    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
                    ' arnelgp
                    If bolUniqueValuesOnly Then
                        If dictValues.Exists(rsMV(0) & "") = False Then
                            dictValues.Add key:=rsMV(0) & "", Item:=rsMV(0).value
                        End If
                    Else
                        i = i + 1
                        dictValues.Add key:=i & "", Item:=rsMV(0).value
                    End If
                    'strOut = strOut & rsMV(0) & strSeparator
                End If
                rsMV.MoveNext
            Loop
            Set rsMV = Nothing
        ElseIf Not IsNull(rs(0)) Then
            ' arnelgp
            If bolUniqueValuesOnly Then
                If dictValues.Exists(rs(0) & "") = False Then
                    dictValues.Add key:=rs(0) & "", Item:=rs(0).value
                End If
            Else
                i = i + 1
                dictValues.Add key:=i & "", Item:=rs(0).value
            End If
            'strOut = strOut & rs(0) & strSeparator
        End If
        rs.MoveNext
    Loop
    rs.Close
    ' arnelgp
    i = dictValues.count
    If i <> 0 Then
        ReDim arrValues(dictValues.count - 1)
        Dim Items As Variant
        Items = dictValues.Items
        For i = 0 To UBound(Items)
            arrValues(i) = Items(i)
        Next
        ConcatRelated = Join(arrValues, strSeparator)
    End If
  
    '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 dictValues = Nothing
    Erase arrValues
    Set rsMV = Nothing
    Set rs = Nothing
    Exit Function

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

create a Query:

SELECT Product, ConcatRelated("Category","yourTable","Product = '" & [Product] & "'", , " ", False) As Categories
FROM yourTable GROUP BY Product;
Thanks. Took a bit of time to figure out but works like a dream. Awesome to get such help so quickly
 

Pat Hartman

Super Moderator
Staff member
Local time
Today, 05:18
Joined
Feb 19, 2002
Messages
43,374
Although the cross tab wizard only accepts three fields, you can open the query in design view after the wizard is finished and add as many as you need.
 

Users who are viewing this thread

Top Bottom