Results 1 to 6 of 6
  1. #1
    Sarah_ is offline Novice
    Windows 7 32bit Access 2010 32bit
    Join Date
    Apr 2012
    Posts
    3

    Add in a field that numbers how many fields with a certain ID

    Sorry if the thread title is not clear, I couldn't think of a more clear way to phrase it

    I have a table that looks like this:

    ID Biologic
    1 Adalimumab
    1 Etanercept
    2
    2 Adalimumab
    3
    3 Adalimumab
    4
    4 Rituximab
    5 Adalimumab
    5 Golimumab

    I want the table to have another field telling me the number of fields with that ID Type like so:

    ID Biologic FieldCount
    1 Adalimumab 1
    1 Etanercept 2
    2 1
    2 Adalimumab 2
    3 1
    3 Adalimumab 2
    3 3
    4 Rituximab 1
    5 Adalimumab 1
    5 Golimumab 2

    How can this be achieved?

    Alternatively, something like this would be ideal:

    ID Biologic Biologic2 Biologic3
    1 Adalimumab Etanercept
    2 Adalimumab
    3 Adalimumab
    4 Rituximab
    5 Adalimumab Golimumab

    Does anyone know how this can be achieved?

  2. #2
    orange's Avatar
    orange is offline Moderator
    Windows XP Access 2003
    Join Date
    Sep 2009
    Location
    Ottawa, Ontario, Canada; West Palm Beach FL
    Posts
    16,848
    I think you need to structure (Normalize) your table.
    How can the same Id occur multiple times? What does Id mean?

    Do not store calculated values in a table.
    To calculate how many times some value occurs in a table, use a query.

  3. #3
    Sarah_ is offline Novice
    Windows 7 32bit Access 2010 32bit
    Join Date
    Apr 2012
    Posts
    3
    Sorry, I should have been clearer, the table is the result of another query. I'm not sure how having a unique ID would help me though.

    I need a query that will produce what I have shown, the reason normalisation isn't a priority is that I am trying to make a flat file for statistical analysis in a package like SPSS.

    I don't care how I get there, I just need a bit of a hack!

  4. #4
    orange's Avatar
    orange is offline Moderator
    Windows XP Access 2003
    Join Date
    Sep 2009
    Location
    Ottawa, Ontario, Canada; West Palm Beach FL
    Posts
    16,848
    OK then please describe what you need exactly. What do the fields mean? How does the output relate to the input?

  5. #5
    Sarah_ is offline Novice
    Windows 7 32bit Access 2010 32bit
    Join Date
    Apr 2012
    Posts
    3
    So each ID is a unique ID from a table, I've got a big dirty pile of data and am trying to modify it through access into a workable flat file. I need a little mini index beside each row that will help me put multiple rows into a single row so that the ID once again becomes a unique identifier.

    So before is:

    ID Biologic
    1 MedicationA
    1 MedicationB
    2 MedicationA
    2 MedicationB
    3 MedicationB

    And after is:

    ID Biologic1 Biologic2
    1 MedicationA MedicationB
    2 MedicationA MedicationB
    3 MedicationB


    Does that make any sense? Sorry I know this is a difficult one to describe, hence no luck googling!

  6. #6
    orange's Avatar
    orange is offline Moderator
    Windows XP Access 2003
    Join Date
    Sep 2009
    Location
    Ottawa, Ontario, Canada; West Palm Beach FL
    Posts
    16,848
    I have set up a test using your data.

    table is called OrigBiolog with fields

    Id number
    Biologic text


    id biologic
    1 MedicationA
    1 MedicationB
    2 MedicationA
    2 MedicationB
    3 MedicationB


    Query:
    SELECT distinct OrigBiolog.id, Concatrelated("Biologic","OrigBiolog","Id=" & [Id] ) AS ConcatBiolog
    FROM OrigBiolog;


    A jpg of the output is attached.


    This function is from Allen Browne and is key to the proper output.
    Code:
    '---------------------------------------------------------------------------------------
    ' Procedure : ConcatRelated
    ' Author    : AllenBrowne
    ' Date      : 12-11-2011
    ' Purpose   :
    '---------------------------------------------------------------------------------------
    ' Last Modified:
    '
    ' Inputs: N/A
    ' Dependency: N/A
    '--------------------------------------------------------------------------
    '
    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   'distinct jed@@@@@
        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

    Good luck with your project.
    Attached Thumbnails Attached Thumbnails BiologicSarah.jpg  

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

Similar Threads

  1. Converting date field in numbers
    By mercapto in forum Queries
    Replies: 5
    Last Post: 04-19-2012, 11:35 AM
  2. Replies: 3
    Last Post: 01-27-2012, 05:32 PM
  3. Assigning numbers to certain fields
    By smartflashes in forum Programming
    Replies: 6
    Last Post: 01-19-2012, 05:14 PM
  4. Import Errors - Fields with Numbers and Letters
    By Eekers in forum Import/Export Data
    Replies: 5
    Last Post: 01-10-2012, 02:52 PM
  5. Setting Field Properties for Numbers
    By Tim Hardison in forum Access
    Replies: 1
    Last Post: 12-09-2009, 06:47 AM

Tags for this Thread

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