Results 1 to 12 of 12
  1. #1
    skydivetom is offline VIP
    Windows 8 Access 2010 64bit
    Join Date
    Feb 2019
    Posts
    1,103

    Crosstab query for up to 16 Yes/No fields

    Hello:

    I would like to get some recommendations with setting up a crosstab query. I believe a have a data set that just "screams CROSSTAB" but I'm not entirely certain how to set it up given the large number of Boolean fields.

    Background:
    - Attached DB contains a table with 30 sample records.
    - Table [tblExampleData] contains 18 fields where [ID] contains distinct autonumber AND [SECTION_NUM] includes 10 records = "1" and 20 records = "2".
    - The remaining 16 fields are all Yes/No fields...


    - ... where values across fields [DATA_TYPE_DATE], [DATA_TYPE_INT], [DATA_TYPE_REAL], [DATA_TYPE_VARCHAR] can only exist in one or the other of these 4 fields
    - ... alternatively, for the remaining 12 fields ([NULL], [B], [C], [D], ..., ..., [F]), there can be any number of records = TRUE. **

    ** Please note the one-letter fields names, e.g., [B], [C], [D], etc. are abbreviations for longer fieldname strings. That's just how the customer shortened them.

    Additional Information:
    - I currently have a query "qry01_Count_for_B_With_SectionNumber" which only includes field [B] and its associated count of {10, 2, 18} for [SECTION_NUM] = {1, 2} & TRUE/FALSE.
    - I think it would be perfectly fine to remove field [SECTION_NUM] from that query. Thus, "qry02_Count_for_B_Without_SectionNumber", I get values {2, 28} based on field [B] = TRUE/FALSE, respectively.
    - The 2nd query (without [ID]) appears to be the preferred method... i.e., I don't think I need to separate my records by section number in the crosstab... unless it is very easy do to (i.e., include/exclude it).
    - Well, [ID] maybe required for the CROSSTAB... not entirely certain here.

    My question:
    - How can I create a crosstab query that creates a matrix of the 16 Boolean fields?

    Final Comments:
    - Again, maybe somehow it is field [ID] by/over ([DATA_TYPE_INT], [DATA_TYPE_REAL], [DATA_TYPE_VARCHAR]).
    - A 2nd query would be field [ID] by/over ([NULL], [B], [C], [D], ..., ..., [F]).
    - However, if these two can be merged, that'll be fine too.

    I'd welcome any recommendations how to best display/output this very simplified data set in a meaningful crosstab query.

    Thank you,
    EEH
    Attached Files Attached Files

  2. #2
    ranman256's Avatar
    ranman256 is offline VIP
    Windows Vista Access 2010 32bit
    Join Date
    Apr 2014
    Location
    Kentucky
    Posts
    9,550
    make a 'report' table
    that has ALL fields needed.

    run Q1 append your data to this table
    run Q2 that will append a generic record so all fields get a value.

    then run a crosstab query on the report table which now has all values.

  3. #3
    skydivetom is offline VIP
    Windows 8 Access 2010 64bit
    Join Date
    Feb 2019
    Posts
    1,103
    Hi - what's the difference between the 'report' table and the existing table?

  4. #4
    June7's Avatar
    June7 is offline VIP
    Windows 10 Access 2010 32bit
    Join Date
    May 2011
    Location
    The Great Land
    Posts
    53,770
    Why mutually-exclusive yes/no fields? Why not 1 field with choices (a combobox)? In your case there would be 2 fields with choices, DataType and Data.

    You want a matrix that counts yeses and noes for each?

    Does this get what you want:

    Query1:
    SELECT Section_Num, "B" AS Src, B AS Data FROM tblExampleData
    UNION ALL SELECT Section_Num, "C", C AS Data FROM tblExampleData
    UNION ALL SELECT Section_Num, "D", C AS Data FROM tblExampleData
    UNION ALL SELECT Section_Num, "E", C AS Data FROM tblExampleData
    UNION ALL SELECT Section_Num, "F", C AS Data FROM tblExampleData
    UNION ALL SELECT Section_Num, "G", C AS Data FROM tblExampleData
    UNION ALL SELECT Section_Num, "L", C AS Data FROM tblExampleData
    UNION ALL SELECT Section_Num, "O", C AS Data FROM tblExampleData
    UNION ALL SELECT Section_Num, "R", C AS Data FROM tblExampleData
    UNION ALL SELECT Section_Num, "S", C AS Data FROM tblExampleData
    UNION ALL SELECT Section_Num, "P", C AS Data FROM tblExampleData;

    Query2:
    TRANSFORM Count(Query1.Data) AS CountOfData
    SELECT IIf([Data],"Y","N") AS YN
    FROM Query1
    GROUP BY IIf([Data],"1","0")
    PIVOT Query1.Src;
    How to attach file: http://www.accessforums.net/showthread.php?t=70301 To provide db: copy, remove confidential data, run compact & repair, zip w/Windows Compression.

  5. #5
    skydivetom is offline VIP
    Windows 8 Access 2010 64bit
    Join Date
    Feb 2019
    Posts
    1,103
    June7 -- thank you for the response.

    Merging 4 fields (DataType) would work. Values are distinct.

    I am hesitant to say the same for the other 12 fields.

    I'll check out your queries when I return home.

  6. #6
    Gicu's Avatar
    Gicu is offline VIP
    Windows 10 Access 2010 32bit
    Join Date
    Jul 2015
    Location
    Kelowna, BC, Canada
    Posts
    4,250
    Hi Tom,

    Not sure a crosstab is what you describe with your matrix, crosstabs take the values from a field and transpose them as columns, not from different fields as you
    suggest.

    Please review the attached file where I created a temporary table to hold the summary information for the yes\No fields (basically copied the source table and changed the data type from Yes\No to long integer to hold the counts).

    Cheers,
    Attached Files Attached Files
    Vlad Cucinschi
    MS Access Developer
    http://forestbyte.com/

  7. #7
    skydivetom is offline VIP
    Windows 8 Access 2010 64bit
    Join Date
    Feb 2019
    Posts
    1,103
    June 7 -- when executing Query2, I get an Aggregate error. See attached JPG.
    Attached Thumbnails Attached Thumbnails Query2.JPG  

  8. #8
    skydivetom is offline VIP
    Windows 8 Access 2010 64bit
    Join Date
    Feb 2019
    Posts
    1,103
    Vlad -- thanks for chiming in on this one... How was the TMP table created? I didn't see type of MakeTable query which would auto-generate it during the next update/change.

    Just trying to gain a better understanding about this method. Thanks.

  9. #9
    Gicu's Avatar
    Gicu is offline VIP
    Windows 10 Access 2010 32bit
    Join Date
    Jul 2015
    Location
    Kelowna, BC, Canada
    Posts
    4,250
    Hi Tom,

    I just manually copied the original table (structure only) then opened the new one in design view and removed the ID then changed the Yes\No fields to Number (long). It could be probably automated but I did not have enough info on the intended uses\specifics.

    Cheers,
    Vlad Cucinschi
    MS Access Developer
    http://forestbyte.com/

  10. #10
    June7's Avatar
    June7 is offline VIP
    Windows 10 Access 2010 32bit
    Join Date
    May 2011
    Location
    The Great Land
    Posts
    53,770
    I don't know why you would get that error. Posted queries work for me.
    How to attach file: http://www.accessforums.net/showthread.php?t=70301 To provide db: copy, remove confidential data, run compact & repair, zip w/Windows Compression.

  11. #11
    skydivetom is offline VIP
    Windows 8 Access 2010 64bit
    Join Date
    Feb 2019
    Posts
    1,103
    Hello:

    I very much apologize for the delayed response... 'just one of "those" days. Anyhow, I had another look at the structure. Both recommendations (from June7 and Vlad) opened my aperture to rethink this slightly.

    Attached is (I think) a working solution which outputs the counts by TRUE/FALSE values by fieldname. Again, the recordset containing only 30 records is just an example. It should/will work w/ the full data set (I'm confident).

    Ultimately, I removed the ID number and include the TRUE/FALSE instead. Thanks for the recommendations and feedback, June7 & Vlad.

    Cheers,
    Tom
    Attached Files Attached Files

  12. #12
    skydivetom is offline VIP
    Windows 8 Access 2010 64bit
    Join Date
    Feb 2019
    Posts
    1,103
    Vlad, June7:

    Thank you for the assistance w/ this query. The attached results (see attached) appear to be sufficient and summarize the Boolean fields sufficiently.

    Again, thanks for offering some great ideas.

    Cheers,
    Tom
    Attached Thumbnails Attached Thumbnails Query3.JPG  
    Attached Files Attached Files

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

Similar Threads

  1. Replies: 3
    Last Post: 01-01-2021, 07:14 AM
  2. Replies: 6
    Last Post: 04-26-2020, 04:41 PM
  3. Replies: 2
    Last Post: 03-14-2017, 12:25 PM
  4. Crosstab Query: Memo Fields
    By McArthurGDM in forum Queries
    Replies: 2
    Last Post: 11-12-2014, 04:51 PM
  5. Replies: 4
    Last Post: 03-27-2011, 01:24 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