Google Groups no longer supports new Usenet posts or subscriptions. Historical content remains viewable.
Dismiss

How to group by a boolean expression

3,635 views
Skip to first unread message

Xeno...@gmail.com

unread,
Mar 8, 2007, 2:37:41 PM3/8/07
to
In MSAccess, I can execute the following query:

SELECT
SUM([MyField]) AS SumMyField
FROM
[MyTable]
GROUP BY
[MyOtherField]=13


However, MSSQL conks out at the '=' operator in the "group by"
clause. Is there a way to write such a query for MSSQL that will work
the same way it works in MSAccess?

Alejandro Mesa

unread,
Mar 8, 2007, 2:51:43 PM3/8/07
to
Try:

SELECT
SUM([MyField]) AS SumMyField
FROM
[MyTable]

where
[MyOtherField] = 13;


AMB

Aaron Bertrand [SQL Server MVP]

unread,
Mar 8, 2007, 2:54:33 PM3/8/07
to
Did you mean

SELECT
SUM([MyField]) AS SumMyField
FROM
[MyTable]

WHERE
[MyOtherField]=13;

?

Or maybe:

SELECT
CASE WHEN MyOtherField = 13 THEN 'Yes' ELSE 'No' END,
SumMyField = SUM(MyField)
FROM
MyTable
GROUP BY
CASE WHEN MyOtherField = 13 THEN 'Yes' ELSE 'No' END;

?

Otherwise, maybe you could show some sample data and desired results. I am
no Access guru and I have idea what GROUP BY [boolean expression] is
supposed to do.

--
Aaron Bertrand
SQL Server MVP
http://www.sqlblog.com/
http://www.aspfaq.com/5006


David Portas

unread,
Mar 8, 2007, 3:19:28 PM3/8/07
to

You could do the literal equivalent using a CASE expression. SQL
Server allows expressions in the GROUP BY list but ANSI SQL doesn't so
I would prefer to nest it like this:

SELECT Is13, SUM(MyField) AS SumMyField
FROM
(SELECT MyField,
CASE WHEN MyOtherField=13 THEN 13 ELSE 0 END AS Is13
FROM MyTable) AS t
GROUP BY Is13;

But that's not necessarily the most efficient solution. Here's a
slightly more sophisticated attempt, which may be worth trying:

SELECT Is13,
CASE Is13 WHEN 13
THEN SumMyField13 ELSE SumMyField-SumMyField13 END
FROM
(SELECT 0 UNION ALL SELECT 13) AS t1 (Is13),
(SELECT
SUM(CASE WHEN MyOtherField=13 THEN MyField END),
SUM(MyField)
FROM MyTable)
AS t2 (SumMyField13, SumMyField);

--
David Portas, SQL Server MVP

Whenever possible please post enough code to reproduce your problem.
Including CREATE TABLE and INSERT statements usually helps.
State what version of SQL Server you are using and specify the content
of any error messages.

SQL Server Books Online:
http://msdn2.microsoft.com/library/ms130214(en-US,SQL.90).aspx
--

rpresser

unread,
Mar 8, 2007, 7:08:46 PM3/8/07
to
On Mar 8, 3:19 pm, "David Portas"
<REMOVE_BEFORE_REPLYING_dpor...@acm.org> wrote:

> But that's not necessarily the most efficient solution. Here's a
> slightly more sophisticated attempt, which may be worth trying:
>
> SELECT Is13,
> CASE Is13 WHEN 13
> THEN SumMyField13 ELSE SumMyField-SumMyField13 END
> FROM
> (SELECT 0 UNION ALL SELECT 13) AS t1 (Is13),
> (SELECT
> SUM(CASE WHEN MyOtherField=13 THEN MyField END),
> SUM(MyField)
> FROM MyTable)
> AS t2 (SumMyField13, SumMyField);

I'm boggled by this one ... how does it work?

Is it more efficient than

SELECT 0, SUM(MyField) FROM MyTable Where MyOtherField=13
UNION ALL
SELECT 13, SUM(MyField) FROM MyTable Where MyOtherField<>13

(Assume MyOtherField is properly indexed in both cases)

--CELKO--

unread,
Mar 8, 2007, 11:48:22 PM3/8/07
to
>> However, MSSQL conks out at the '=' operator in the "group by" clause. <<

This is only part of the problem of trying to escape ACCESS. Here is
how a SELECT works in SQL ... at least in theory. Real products will
optimize things, but the code has to produce the same results.

a) Start in the FROM clause and build a working table from all of the
joins, unions, intersections, and whatever other table constructors
are there. The <table expression> AS <correlation name> option allows
you give a name to this working table which you then have to use for
the rest of the containing query.

b) Go to the WHERE clause and remove rows that do not pass criteria;
that is, that do not test to TRUE (i.e. reject UNKNOWN and FALSE).
The WHERE clause is applied to the working set in the FROM clause.

c) Go to the optional GROUP BY clause, partiton the original table
into groups and reduce each grouping to a *single* row, replacing the
original working table with the new grouped table. The rows of a
grouped table must be only group characteristics: (1) a grouping
column (2) a statistic about the group (i.e. aggregate functions) (3)
a function or constant(4) an expression made up of only those three
items. The original table no longer exists and you cannot reference
anything in it (this was an error in early Sybase products).

d) Go to the optional HAVING clause and apply it against the grouped
working table; if there was no GROUP BY clause, treat the entire table
as one group.

e) Go to the SELECT clause and construct the expressions in the list.
This means that the scalar subqueries, function calls and expressions
in the SELECT are done after all the other clauses are done. The AS
operator can also give names to expressions in the SELECT list. These
new names come into existence all at once, but after the WHERE clause,
GROUP BY clause and HAVING clause have been executed; you cannot use
them in the SELECT list or the WHERE clause for that reason.

If there is a SELECT DISTINCT, then redundant duplicate rows are
removed. For purposes of defining a duplicate row, NULLs are treated
as matching (just like in the GROUP BY).

f) Nested query expressions follow the usual scoping rules you would
expect from a block structured language like C, Pascal, Algol, etc.
Namely, the innermost queries can reference columns and tables in the
queries in which they are contained.

g) The ORDER BY clause is part of a cursor, not a query. The result
set is passed to the cursor, which can only see the names in the
SELECT clause list, and the sorting is done there. The ORDER BY
clause cannot have expression in it, or references to other columns
because the result set has been converted into a sequential file
structure and that is what is being sorted.

As you can see, things happen "all at once" in SQL, not "from left to
right" as they would in a sequential file/procedural language model.
In those languages, these two statements produce different results:
READ (a, b, c) FROM File_X;
READ (c, a, b) FROM File_X;

while these two statements return the same data:

SELECT a, b, c FROM Table_X;
SELECT c, a, b FROM Table_X;

Think about what a confused mess this statement is in the SQL model.

SELECT f(c2) AS c1, f(c1) AS c2 FROM Foobar;

That is why such nonsense is illegal syntax.

0 new messages