Results 1 to 15 of 15
  1. #1
    rdougherty is offline Competent Performer
    Windows 7 64bit Access 2016
    Join Date
    Dec 2016
    Location
    Michigan
    Posts
    107

    Count if/where logic for query

    Hello,

    I am looking for a way, if there is one, to count IDs in a query based on special criteria.

    I want one query to build a report record set, that alongside its overall count, has counts of records where X is true.

    Results look like this:



    |Program Name|Count Records|Count Online|

    where, "online" means "Count records where CHannel = Online"

    Can that be done so the one count exists in same query alongside the other?

    Thanks,

  2. #2
    isladogs's Avatar
    isladogs is offline Access MVP / VIP
    Windows 10 Access 2010 32bit
    Join Date
    Jan 2014
    Location
    Somerset, UK
    Posts
    6,204
    There are several ways of doing this including:

    1. Create two aggregate queries, the first with an overall count & the second with the condition
    Now create a new query using the above with no join
    Code:
    SELECT Query1.CountAll, Query2.CountConditionTrue
    FROM Query1, Query2;
    2. Create a query with no table source and use DCount expressions for both items
    Code:
    SELECT DCount("*","Table1") AS CountAll, DCount("*","Table1","Condition=True") AS CountConditionTrue;
    Colin Riddington, Access MVP, Website, email
    The more I learn, the more I know I don't know. When I know I don't know, I keep quiet!

  3. #3
    rdougherty is offline Competent Performer
    Windows 7 64bit Access 2016
    Join Date
    Dec 2016
    Location
    Michigan
    Posts
    107
    Thanks a lot! I Was hoping there was a way of avoiding those two things, but that's okay

  4. #4
    isladogs's Avatar
    isladogs is offline Access MVP / VIP
    Windows 10 Access 2010 32bit
    Join Date
    Jan 2014
    Location
    Somerset, UK
    Posts
    6,204
    Quote Originally Posted by rdougherty View Post
    Thanks a lot! I Was hoping there was a way of avoiding those two things, but that's okay
    Avoiding which two things exactly?
    You can't do it in one simple query if that's what you mean
    Colin Riddington, Access MVP, Website, email
    The more I learn, the more I know I don't know. When I know I don't know, I keep quiet!

  5. #5
    June7's Avatar
    June7 is offline VIP
    Windows 10 Access 2010 32bit
    Join Date
    May 2011
    Location
    The Great Land
    Posts
    53,770
    How does one accomplish option 2? Access query builder does not accept this structure. Must SELECT FROM a table/query.

    SELECT DISTINCT DCount("*","Table1") AS CountAll, DCount("*","Table1","Condition=True") AS CountConditionTrue FROM Table1;

    Possible Option 3:

    SELECT Count([ID]) AS CountAll, Sum(IIf([Channel]='Online',1,0)) AS CountOnLine FROM table1;

    or maybe:

    SELECT ProgramName, Count([ID]) AS CountAll, Sum(IIf([Channel]='Online',1,0)) AS CountOnline FROM table1 GROUP BY ProgramName;

    Or use report Sorting & Grouping features with aggregate calcs in textboxes. This will allow display of detail records as well as summary calcs.
    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.

  6. #6
    rdougherty is offline Competent Performer
    Windows 7 64bit Access 2016
    Join Date
    Dec 2016
    Location
    Michigan
    Posts
    107
    Quote Originally Posted by ridders52 View Post
    Avoiding which two things exactly?
    You can't do it in one simple query if that's what you mean
    Wait... I'm confused. I just tried the following and it is counting records with a Channel of "online" correctly, alongside a normal count.

    Expression:
    Code:
    Count(IIf([tbl_MASTER_Received]![Channel]="Online",[tbl_MASTER_Received]![Unique EA ID]))

  7. #7
    isladogs's Avatar
    isladogs is offline Access MVP / VIP
    Windows 10 Access 2010 32bit
    Join Date
    Jan 2014
    Location
    Somerset, UK
    Posts
    6,204
    Quote Originally Posted by June7 View Post
    How does one accomplish option 2? Access query builder does not accept this structure. Must SELECT FROM a table/query.
    Surprisingly it does work using DCount without any tables but you can only run it in SQL view - I tried it before posting to remind myself that it worked:

    Design view

    Click image for larger version. 

Name:	Capture.1PNG.PNG 
Views:	10 
Size:	34.6 KB 
ID:	33866

    SQL view

    Click image for larger version. 

Name:	Capture2.PNG 
Views:	9 
Size:	35.8 KB 
ID:	33867

    Result

    Click image for larger version. 

Name:	Capture3.PNG 
Views:	9 
Size:	20.4 KB 
ID:	33868
    Colin Riddington, Access MVP, Website, email
    The more I learn, the more I know I don't know. When I know I don't know, I keep quiet!

  8. #8
    isladogs's Avatar
    isladogs is offline Access MVP / VIP
    Windows 10 Access 2010 32bit
    Join Date
    Jan 2014
    Location
    Somerset, UK
    Posts
    6,204
    If you try doing both in one standard aggregate query, you normally get the same value in both columns
    Colin Riddington, Access MVP, Website, email
    The more I learn, the more I know I don't know. When I know I don't know, I keep quiet!

  9. #9
    rdougherty is offline Competent Performer
    Windows 7 64bit Access 2016
    Join Date
    Dec 2016
    Location
    Michigan
    Posts
    107
    Quote Originally Posted by ridders52 View Post
    If you try doing both in one standard aggregate query, you normally get the same value in both columns
    That's what's weird - I have done it, validated it separately, and it appears to work. I have also calculated the % Online using the following:

    Expression:
    Code:
    Count(IIf([tbl_MASTER_Received]![Channel]="Online",[tbl_MASTER_Received]![Unique EA ID]))/Count([tbl_MASTER_Received]![Unique EA ID])
    These are being Grouped by Program, and the counts thus far are valid. When the data gets more complex, I will continue to validate and make sure nothing breaks.

  10. #10
    isladogs's Avatar
    isladogs is offline Access MVP / VIP
    Windows 10 Access 2010 32bit
    Join Date
    Jan 2014
    Location
    Somerset, UK
    Posts
    6,204
    That's not an aggregate query.
    I meant the type of query shown below where you use the Totals button in the ribbon
    Each will work as a separate query which you can then join
    However if you try and do it in one query it doesn't give the correct results
    Below I'm using the same data as my previous screenshots in an aggregate query for the same table added twice

    Click image for larger version. 

Name:	Capture4.PNG 
Views:	8 
Size:	47.4 KB 
ID:	33869

    This time both results are identical - its useless for this purpose

    Click image for larger version. 

Name:	Capture5.PNG 
Views:	8 
Size:	16.2 KB 
ID:	33870
    Colin Riddington, Access MVP, Website, email
    The more I learn, the more I know I don't know. When I know I don't know, I keep quiet!

  11. #11
    June7's Avatar
    June7 is offline VIP
    Windows 10 Access 2010 32bit
    Join Date
    May 2011
    Location
    The Great Land
    Posts
    53,770
    I see, have to click Run button from SQL View, not switch to DatasheetView by right click shortcut. Or save and open from Navigation Pane. Learn something new.

    If you wanted count for each distinct value of [Channel] field (how many possible?), there would be complication but since you want only the 'Online' records counted, is simple.

    I think it is still an aggregate query because aggregate functions are employed and I use the Totals button to get the Totals row. See post 5 for aggregate queries with and without GROUP BY.
    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.

  12. #12
    isladogs's Avatar
    isladogs is offline Access MVP / VIP
    Windows 10 Access 2010 32bit
    Join Date
    Jan 2014
    Location
    Somerset, UK
    Posts
    6,204
    Yes - I agree that option 3 is also fine. In my example from the screenshots it is:
    Code:
    SELECT Count("*") AS CountAll, Sum(IIf([InUse]=True,1,0)) AS CountInUse
    FROM PostcodeDistricts;
    I suppose it's a question of semantics really - I only refer to aggregate queries where the Totals row is involved ...
    I may be wrong in doing so but this link uses the term as I do: https://www.teachucomp.com/aggregate...cess-tutorial/

    This MS link https://msdn.microsoft.com/en-us/lib...ffice.12).aspx refers to aggregate functions for the above type of code:

    Anyway, looks like the OP is spoiled for choice on this task!
    Colin Riddington, Access MVP, Website, email
    The more I learn, the more I know I don't know. When I know I don't know, I keep quiet!

  13. #13
    rdougherty is offline Competent Performer
    Windows 7 64bit Access 2016
    Join Date
    Dec 2016
    Location
    Michigan
    Posts
    107
    The query I gave a portion of above, is actually using the Totals/Grouping function. It is grouping by categorical data, and then is using the iif statements to qualify how to count records. I have validated it is working 100% with my data... I don't know why it wouldn't work with other data.

    If someone could articulate a logic problem that would result in doing so, please do.

  14. #14
    isladogs's Avatar
    isladogs is offline Access MVP / VIP
    Windows 10 Access 2010 32bit
    Join Date
    Jan 2014
    Location
    Somerset, UK
    Posts
    6,204
    Just for my own interest I tried the 3 methods on another postcodes table with over 2.6 million records to compare the times taken

    Method 1 - using 2 aggregate queries combined with a cartesian join - took <3 seconds
    Code:
    Query1A: SELECT Count(Table1.FieldName) AS CountAll FROM Table1;
    Query1B: SELECT Count(Table1.FieldName) AS CountConditionTrue FROM Table1 WHERE Condition=True;
    Cartesian join: SELECT Query1A.CountAll, Query1B.CountConditionTrue FROM Query1A, Query1B;
    Method 2 - using DCount - took 9 seconds - much longer as I expected
    Code:
    SELECT DCount("*","Table1") AS CountAll, DCount("*","Table1","Condition=True") AS CountConditionTrue;
    Method 3 - single query using aggregate functions - took 4 seconds
    Code:
    SELECT Count("*") AS CountAll, Sum(IIf([InUse]=True,1,0)) AS CountInUse FROM Table1;
    I was surprised to find Method 1 was faster than Method 3

    I also thought it worth trying ...
    Method 4 - which combines methods 1 & 3 - using 2 aggregate function queries combined using a cartesian join - it took 8 seconds
    Query4A: SELECT Count("*") AS CountAll FROM Table1
    Query4B: SELECT Count("*") AS CountConditionTrue FROM Table1 WHERE Condtion=True
    Cartesian join: SELECT Query4A.CountAll, Query4B.CountConditionTrue FROM Query4A, Query4B;[/CODE]

    All methods work & give correct answers. HTH somebody else trying to decide which method to use
    Last edited by isladogs; 05-04-2018 at 06:09 PM. Reason: Corrected errors
    Colin Riddington, Access MVP, Website, email
    The more I learn, the more I know I don't know. When I know I don't know, I keep quiet!

  15. #15
    isladogs's Avatar
    isladogs is offline Access MVP / VIP
    Windows 10 Access 2010 32bit
    Join Date
    Jan 2014
    Location
    Somerset, UK
    Posts
    6,204
    Quote Originally Posted by rdougherty View Post
    The query I gave a portion of above, is actually using the Totals/Grouping function. It is grouping by categorical data, and then is using the iif statements to qualify how to count records. I have validated it is working 100% with my data... I don't know why it wouldn't work with other data.

    If someone could articulate a logic problem that would result in doing so, please do.
    Please post the full query & I'll test an equivalent with my own data ... or is it like one of the methods 1-4 in my previous post?
    Colin Riddington, Access MVP, Website, email
    The more I learn, the more I know I don't know. When I know I don't know, I keep quiet!

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

Similar Threads

  1. Query logic for two different complex reports
    By xboxown in forum Reports
    Replies: 3
    Last Post: 12-14-2017, 06:54 PM
  2. Replies: 5
    Last Post: 02-08-2017, 05:52 PM
  3. Replies: 2
    Last Post: 06-30-2016, 06:38 PM
  4. Query Producing Blank Rows? Fault IIf Logic?
    By kestefon in forum Access
    Replies: 6
    Last Post: 12-18-2013, 06:13 PM
  5. SQL Query - Understanding the logic.
    By BayEnder in forum Access
    Replies: 2
    Last Post: 02-17-2013, 12:45 PM

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