Tuesday, March 27, 2012

Derived Fields

Guys, this is what I want to do. How can I do this ?

Select employid,
Gross=( Select sum (uprtrxam) from Fleet..upr30300 where pyrlrtyp=1),
DedofWages=( Select sum (uprtrxam) from Fleet..upr30300 where
pyrltyp=2),
Gross-DedofWages
from FLEET..UPR00100

The problem is the third field (Gross-DedofWages). It says Invalid
column. Any ideas ?

Thanks, GirishIt doesn't look like your query would give the result you expected
anyway - the subqueries aren't correlated. Try this:

SELECT U.employid, T.gross, T.dedofwages,
T.gross - T.dedofwages
FROM Fleet..upr00100 AS U
LEFT JOIN
(SELECT employid,
CASE WHEN pyrlrtyp=1 THEN uprtrxam END AS gross,
CASE WHEN pyrlrtyp=2 THEN uprtrxam END AS dedofwages
FROM Fleet..upr30300
WHERE pyrlrtyp BETWEEN 1 AND 2
GROUP BY employid) AS T
ON U.empoyid = T.employeid

The rule is that columns in the SELECT list must exist in the base
tables or derived tables. Aliases aren't allowed.

--
David Portas
SQL Server MVP
--|||Oops. Correction:

SELECT U.employid, T.gross, T.dedofwages,
T.gross - T.dedofwages
FROM upr00100 AS U
LEFT JOIN
(SELECT employid,
SUM(CASE WHEN pyrlrtyp=1 THEN uprtrxam END) AS gross,
SUM(CASE WHEN pyrlrtyp=2 THEN uprtrxam END) AS dedofwages
FROM upr30300
WHERE pyrlrtyp BETWEEN 1 AND 2
GROUP BY employid) AS T
ON U.employid = T.employid

--
David Portas
SQL Server MVP
--|||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, make groups and reduce each
group to a single row, replacing the original working table with the
new grouped table. The rows of a grouped table must be group
characteristics: (1) a grouping column (2) a statistic about the group
(i.e. aggregate functions) (3) a function or (4) an expression made up
those three items.

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 has 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.sql

No comments:

Post a Comment