Query error with aggregate and criteria
Results 1 to 2 of 2

Thread: Query error with aggregate and criteria
Thanks Thanks: 0 Likes Likes: 0

  1. #1
    Board Regular
    Join Date
    May 2004
    Posts
    358
    Post Thanks / Like
    Mentioned
    0 Post(s)
    Tagged
    0 Thread(s)

    Default Query error with aggregate and criteria

    I'm trying in a single query to exclude variances of $0 using data from 2 tables. I create a temp table from 2 queries and query that with aggregates and criteria.

    SELECT x.Vendor, Sum(x.Budget) AS Budget, Sum(x.Actuals) AS Actuals, [Budget]-[Actuals] AS Variance
    FROM (
    SELECT Vendor, 0 AS Budget, Actuals FROM [Vendor Actuals]
    UNION ALL
    SELECT Vendor, Budget, 0 AS Actuals FROM [Vendor Budget]
    ) AS x
    GROUP BY x.Vendor
    HAVING ((([Budget]-[Actuals])<>0));

    The HAVING statement causes this error:

    You tried to execute a query that does not include the specified expression 'Not [Budget]-[Actuals])=0' as part of an aggregate function."

    Using 2 queries I can get the results, where the first query doesn't have the criteria and the second query calls that query with criteria. Of course I prefer avoiding the need for 2 queries.

  2. #2
    MrExcel MVP
    Moderator
    xenou's Avatar
    Join Date
    Mar 2007
    Location
    Clev. OH, USA
    Posts
    16,445
    Post Thanks / Like
    Mentioned
    11 Post(s)
    Tagged
    1 Thread(s)

    Default Re: Query error with aggregate and criteria

    I guess you want a where clause not a having clause?

    Such as:

    Code:
    SELECT x.Vendor, Sum(x.Budget) AS Budget, Sum(x.Actuals) AS Actuals, [Budget]-[Actuals] AS Variance
    FROM (
    SELECT Vendor, 0 AS Budget, Actuals FROM [Vendor Actuals]
    UNION ALL
    SELECT Vendor, Budget, 0 AS Actuals FROM [Vendor Budget]
    ) AS x 
    WHERE ((([Budget]-[Actuals])<>0))
    GROUP BY x.Vendor
    ;

    Given the definition of your subquery X, this is also equivalent:
    Code:
    SELECT x.Vendor, Sum(x.Budget) AS Budget, Sum(x.Actuals) AS Actuals, [Budget]-[Actuals] AS Variance
    FROM (
    SELECT Vendor, 0 AS Budget, Actuals FROM [Vendor Actuals] WHERE Actuals <> 0
    UNION ALL
    SELECT Vendor, Budget, 0 AS Actuals FROM [Vendor Budget] WHERE Budget <> 0
    ) AS x 
    GROUP BY x.Vendor
    ;

    Using: Office 2010/Win7 (work) Office 2010/Win7 (home)

    You are rich in proportion to the number of things you can let alone.
    -- Henry David Thoreau

Some videos you may like

User Tag List

Tags for this Thread

Like this thread? Share it with others

Like this thread? Share it with others

Posting Permissions

  • You may not post new threads
  • You may not post replies
  • You may not post attachments
  • You may not edit your posts
  •