trying to add alias for value generated by Where clause

  • Unless I comment out the alias 'AS RunningTotal' the query fails, but I need an alias for the column the WHERE STATEMENT generates. Will someone please show me how to get an alias for the RunningTotal column?

    Both query and DDL are taken from the following website:

    http://www.sqlteam.com/article/calculating-running-totals

    ---QUERY that returns cumulative total by DayCount

    SELECT a.DayCount,

    a.Sales,

    SUM(b.Sales)

    FROM Sales a

    CROSS JOIN Sales b

    WHERE (b.DayCount <= a.DayCount) --AS RunningTotal

    GROUP BY a.DayCount,a.Sales

    ORDER BY a.DayCount,a.Sales

    ---DDL

    CREATE TABLE Sales (DayCount smallint, Sales money)

    CREATE CLUSTERED INDEX ndx_DayCount ON Sales(DayCount)

    go

    INSERT Sales VALUES (1,120)

    INSERT Sales VALUES (2,60)

    INSERT Sales VALUES (3,125)

    INSERT Sales VALUES (4,40)

    DECLARE @DayCount smallint, @Sales money

    SET @DayCount = 5

    SET @Sales = 10

    WHILE @DayCount < 5000

    BEGIN

    INSERT Sales VALUES (@DayCount,@Sales)

    SET @DayCount = @DayCount + 1

    SET @Sales = @Sales + 15

    END

    --Quote me

  • You can't add an alias in a WHERE clause, so it's probably a mistake in the article. It probably needs to be appended after SUM(b.Sales), not after the WHERE clause.

    The article is out-of-date by the way, as SQL Server 2012 introduces windowing functions which outperform every solution presented in the article, even the cursor one.

    Need an answer? No, you need a question
    My blog at https://sqlkover.com.
    MCSE Business Intelligence - Microsoft Data Platform MVP

  • polkadot (7/31/2012)


    ---QUERY that returns cumulative total by DayCount

    SELECT a.DayCount,

    a.Sales,

    SUM(b.Sales)

    FROM Sales a

    CROSS JOIN Sales b

    WHERE (b.DayCount <= a.DayCount) --AS RunningTotal

    GROUP BY a.DayCount,a.Sales

    ORDER BY a.DayCount,a.Sales

    Be very careful there. What you've got is a triangular join, which is going to cost a lot in terms of performance. Have a look at this article --> http://www.sqlservercentral.com/articles/T-SQL/61539/%5B/url%5D for more information.


    Forever trying to learn
    My blog - http://www.cadavre.co.uk/
    For better, quicker answers on T-SQL questions, click on the following...http://www.sqlservercentral.com/articles/Best+Practices/61537/
    For better, quicker answers on SQL Server performance related questions, click on the following...http://www.sqlservercentral.com/articles/SQLServerCentral/66909/

  • polkadot (7/31/2012)


    ... I need an alias for the column the WHERE STATEMENT generates...

    The WHERE clause doesn't generate an output column. Ever.

    There are four well-known ways to calculate running totals in SS2k8:

    1. Quirky update - fastest

    2. Recursive CTE

    3. Cursor

    4. Triangular Join - usually slowest but depends upon partitioning.

    The code you've posted is an attempt at coding the TJ method. If the number of elements in each GROUP BY partition is small compared to the entire data set then it may be worth pursuing, however most folks would recommend the QU for speed or the rCTE for ease of coding.

    “Write the query the simplest way. If through testing it becomes clear that the performance is inadequate, consider alternative query forms.” - Gail Shaw

    For fast, accurate and documented assistance in answering your questions, please read this article.
    Understanding and using APPLY, (I) and (II) Paul White
    Hidden RBAR: Triangular Joins / The "Numbers" or "Tally" Table: What it is and how it replaces a loop Jeff Moden

  • ChrisM@Work (8/1/2012)


    polkadot (7/31/2012)


    ... I need an alias for the column the WHERE STATEMENT generates...

    The WHERE clause doesn't generate an output column. Ever.

    There are four well-known ways to calculate running totals in SS2k8:

    1. Quirky update - fastest

    2. Recursive CTE

    3. Cursor

    4. Triangular Join - usually slowest but depends upon partitioning.

    The code you've posted is an attempt at coding the TJ method. If the number of elements in each GROUP BY partition is small compared to the entire data set then it may be worth pursuing, however most folks would recommend the QU for speed or the rCTE for ease of coding.

    The quirky update method relies on undocumented behaviour if I'm not mistaken, and is thus unreliable. For very large datasets, the cursor method is actually the preferred method.

    Luckily window functions are introduced in SQL 2012 🙂

    Need an answer? No, you need a question
    My blog at https://sqlkover.com.
    MCSE Business Intelligence - Microsoft Data Platform MVP

  • Koen Verbeeck (8/1/2012)


    ChrisM@Work (8/1/2012)


    polkadot (7/31/2012)


    ... I need an alias for the column the WHERE STATEMENT generates...

    The WHERE clause doesn't generate an output column. Ever.

    There are four well-known ways to calculate running totals in SS2k8:

    1. Quirky update - fastest

    2. Recursive CTE

    3. Cursor

    4. Triangular Join - usually slowest but depends upon partitioning.

    The code you've posted is an attempt at coding the TJ method. If the number of elements in each GROUP BY partition is small compared to the entire data set then it may be worth pursuing, however most folks would recommend the QU for speed or the rCTE for ease of coding.

    The quirky update method relies on undocumented behaviour if I'm not mistaken, and is thus unreliable. For very large datasets, the cursor method is actually the preferred method.

    Luckily window functions are introduced in SQL 2012 🙂

    There will be opinions about this 🙂

    variable = column = expression is documented in both UPDATE and MERGE but MS give no clue about usage. Then again, MS are lousy at providing examples and showing how a feature should be used.

    If the running total is to be persisted, I'll usually go for the QU. If it's for output (reporting) I'll always go for a rCTE from a suitably indexed #temp table, because it's likely to be quicker than a cursor or a TJ.

    “Write the query the simplest way. If through testing it becomes clear that the performance is inadequate, consider alternative query forms.” - Gail Shaw

    For fast, accurate and documented assistance in answering your questions, please read this article.
    Understanding and using APPLY, (I) and (II) Paul White
    Hidden RBAR: Triangular Joins / The "Numbers" or "Tally" Table: What it is and how it replaces a loop Jeff Moden

  • Having looked at the article, it looks like the 'AS' clause is in the wrong place. It should be like this, I think

    SELECT a.DayCount,

    a.Sales,

    SUM(b.Sales) AS RunningTotal

    FROM Sales a

    CROSS JOIN Sales b

    WHERE (b.DayCount <= a.DayCount)

    GROUP BY a.DayCount,a.Sales

    ORDER BY a.DayCount,a.Sales

  • laurie-789651 (8/1/2012)


    Having looked at the article, it looks like the 'AS' clause is in the wrong place. It should be like this, I think

    SELECT a.DayCount,

    a.Sales,

    SUM(b.Sales) AS RunningTotal

    FROM Sales a

    CROSS JOIN Sales b

    WHERE (b.DayCount <= a.DayCount)

    GROUP BY a.DayCount,a.Sales

    ORDER BY a.DayCount,a.Sales

    AFAIK, there is no such thing as an 'AS' clause in T-SQL.

    In the code you provide, the 'AS' can be omitted.

    If you haven't even tried to resolve your issue, please don't expect the hard-working volunteers here to waste their time providing links to answers which you could easily have found yourself.

  • polkadot (7/31/2012)


    Unless I comment out the alias 'AS RunningTotal' the query fails, but I need an alias for the column the WHERE STATEMENT generates. Will someone please show me how to get an alias for the RunningTotal column?

    Both query and DDL are taken from the following website:

    http://www.sqlteam.com/article/calculating-running-totals

    ---QUERY that returns cumulative total by DayCount

    SELECT a.DayCount,

    a.Sales,

    SUM(b.Sales)

    FROM Sales a

    CROSS JOIN Sales b

    WHERE (b.DayCount <= a.DayCount) --AS RunningTotal

    GROUP BY a.DayCount,a.Sales

    ORDER BY a.DayCount,a.Sales

    ---DDL

    CREATE TABLE Sales (DayCount smallint, Sales money)

    CREATE CLUSTERED INDEX ndx_DayCount ON Sales(DayCount)

    go

    INSERT Sales VALUES (1,120)

    INSERT Sales VALUES (2,60)

    INSERT Sales VALUES (3,125)

    INSERT Sales VALUES (4,40)

    DECLARE @DayCount smallint, @Sales money

    SET @DayCount = 5

    SET @Sales = 10

    WHILE @DayCount < 5000

    BEGIN

    INSERT Sales VALUES (@DayCount,@Sales)

    SET @DayCount = @DayCount + 1

    SET @Sales = @Sales + 15

    END

    The fastest methods (QU, rCTE, Cursors) have been mentioned already. I recently tested this (following a lively discussion on this topic) and here is what I found:

    The slower methods include:

    -- A. COALESCE method (9sec for 5K records, 2:30 for 20K)

    BEGIN

    SELECT [Day],

    Sales,

    Sales+

    COALESCE((SELECT SUM(Sales)

    FROM ##Sales b

    WHERE b.[Day] < a.[Day]),0) AS [Running Total]

    FROM ##Sales a

    ORDER BY [Day]

    END

    GO

    -- B. Cross Join method (2sec for 5K records, 0:26 for 20K)

    SELECT a.[Day],

    a.Sales,

    SUM(b.Sales) [Running Total]

    FROM ##Sales a

    CROSS JOIN ##Sales b

    WHERE (b.[Day] <= a.[Day])

    GROUP BY a.[Day],a.Sales

    ORDER BY a.[Day],a.Sales

    -- NOTE: B & C have the same query plan.

    -- C. Self Join method; Equal to B (2sec for 5K records, 0:26 for 20K)

    SELECT a.[Day],

    a.Sales,

    SUM(b.Sales) [Running Total]

    FROM ##Sales a

    JOIN ##Sales b

    ON (b.[Day] <= a.[Day])

    GROUP BY a.[Day],a.Sales

    ORDER BY a.[Day],a.Sales

    -- D. Cross Apply/Self-Join method (4 sec for 5K records, 1:09 for 20K)

    SELECT[Day],

    [Sales],

    [Running Total]

    FROM ##Sales a

    CROSS APPLY

    (

    SELECT [Running Total] = sum(Sales)

    FROM ##Sales

    WHERE [Day] <= a.[Day]

    ) RT

    ORDER BY [Day];

    You are using the cross join method (B).

    As you can see, these methods become painfully slow once you hit 20K records.

    Now, looking at the aforementioned faster methods:

    -- E. rCTE method - Very fast, (17 sec for 1M rows)

    ;WITH CTE ([Day], [Sales], [Running Total])

    AS

    (

    SELECT[Day],

    [Sales],

    [Sales]

    FROM ##Sales

    WHERE [Day] = 1

    UNION ALL

    SELECTa.[Day],

    a.[Sales],

    CTE.[Running Total] + a.[Sales]

    FROM CTE

    JOIN ##Sales a ON CTE.[Day] + 1 = a.[Day]

    )

    SELECT * FROM CTE

    OPTION (MAXRECURSION 0)

    GO

    -- F. "Quirky Update" Method (fastest, 12 sec for 1M rows)

    DECLARE @PrevDay INT, @RunningTotal MONEY = 0

    DECLARE @sales TABLE

    (

    [Day#]int,

    [Sales#]MONEY,

    [RunningTotal]MONEY,

    PRIMARY KEY([Day#] ASC)

    );

    INSERT INTO @sales ([Day#],[Sales#])

    SELECT * FROM ##Sales;

    UPDATE @sales

    SET @RunningTotal = RunningTotal =CASE

    WHEN [Day] = @PrevDay

    THEN @RunningTotal+[Sales#]

    ELSE Sales#

    END,

    @PrevDay = [Day]

    FROM ##Sales WITH (TABLOCKX)

    OPTION (MAXDOP 1)

    SELECT * FROM @sales

    GO

    -- G. Optimized Cursor, (44sec for 1M rows, 70 seconds without FAST_FORWARD)

    BEGIN

    DECLARE @Day int, @Sales money

    DECLARE @RunningTotal money = 0

    DECLARE @SalesTbl_2 TABLE

    (

    [Day]int,

    Salesmoney,

    RunningTotalmoney,

    PRIMARY KEY([Day])

    )

    DECLARE rt_cursor CURSOR FAST_FORWARD FOR

    SELECT [Day], Sales

    FROM ##Sales

    ORDER BY [Day]

    OPEN rt_cursor

    FETCH NEXT

    FROM rt_cursor

    INTO @Day,@Sales

    WHILE @@FETCH_STATUS = 0

    BEGIN

    SET @RunningTotal = @RunningTotal + @Sales

    INSERT @SalesTbl_2

    VALUES (@Day,@Sales,@RunningTotal)

    FETCH NEXT FROM rt_cursor INTO @Day,@Sales

    END

    CLOSE rt_cursor

    DEALLOCATE rt_cursor

    SELECT [Day],Sales,RunningTotal FROM @SalesTbl_2

    END

    GO

    Each of these guys will blast through several hundred thousand rows in seconds. QU is still new to me and I'm playing around with it - it is usually the fastest. I personally prefer the rCTE because, though it's slighltly slower than the QU method, it's the most elegant and easiest to read (IMHO) of the faster solutions.

    The other take-away from my testing is that cursors get a bad rap (and often rightfully so) but, in this case, a cursor is faster than all but a the QU and rCTE methods. It's also worth noting the performance difference using FAST_FORWARD with cursors when appropriate.

    "I cant stress enough the importance of switching from a sequential files mindset to set-based thinking. After you make the switch, you can spend your time tuning and optimizing your queries instead of maintaining lengthy, poor-performing code."

    -- Itzik Ben-Gan 2001

  • XMLSQLNinja (8/1/2012)<<snip>>

    Each of these guys will blast through several hundred thousand rows in seconds. QU is still new to me and I'm playing around with it - it is usually the fastest. I personally prefer the rCTE because, though it's slighltly slower than the QU method, it's the most elegant and easiest to read (IMHO) of the faster solutions.

    The other take-away from my testing is that cursors get a bad rap (and often rightfully so) but, in this case, a cursor is faster than all but a the QU and rCTE methods. It's also worth noting the performance difference using FAST_FORWARD with cursors when appropriate.

    That's exactly what I'd expect to see. Methods A,B,C and D are all triangular join methods which can have huge working tables. I'd agree with your cursor conclusions too - Hugo Cornelis' article provides useful guidelines for writing fast cursor processing.

    “Write the query the simplest way. If through testing it becomes clear that the performance is inadequate, consider alternative query forms.” - Gail Shaw

    For fast, accurate and documented assistance in answering your questions, please read this article.
    Understanding and using APPLY, (I) and (II) Paul White
    Hidden RBAR: Triangular Joins / The "Numbers" or "Tally" Table: What it is and how it replaces a loop Jeff Moden

  • Alan aka XMLSQLNinja. Thank you very much for the careful response and particularly for the rCTE. It was what I was after, but I had not felt I had done my best effort yet to figure it out for myself to ask for the actualy rCTE. I will examine all queries and again THANK YOU!!!

    p.s. Your CTE should look like this. (Day column should be DayCount)

    ;WITH CTE ([DayCount], [Sales], [Running Total])

    AS

    (

    SELECT[DayCount],

    [Sales],

    [Sales]

    FROM Sales

    WHERE [DayCount] = 1

    UNION ALL

    SELECTa.[DayCount],

    a.[Sales],

    CTE.[Running Total] + a.[Sales]

    FROM CTE

    JOIN Sales a ON CTE.[DayCount] + 1 = a.[DayCount]

    )

    SELECT * FROM CTE

    OPTION (MAXRECURSION 0)

    GO

    --Quote me

  • How would you build rCTE when the column against which recursion is done is a SMALLDATETIME column and not SMALLINT?

    Do I need to first order the dates using rank or rowcount, and then use the rowcount column for setting the recursion element?

    --Quote me

  • polkadot (8/2/2012)


    How would you build rCTE when the column against which recursion is done is a SMALLDATETIME column and not SMALLINT?

    Do I need to first order the dates using rank or rowcount, and then use the rowcount column for setting the recursion element?

    You'd treat it almost exactly the same way. DATETIME (and derivatives) are merely numerics under the hood with special wrappers. However you deal with your code using SMALLINT it should take a SMALLDATETIME just as easily.


    - Craig Farrell

    Never stop learning, even if it hurts. Ego bruises are practically mandatory as you learn unless you've never risked enough to make a mistake.

    For better assistance in answering your questions[/url] | Forum Netiquette
    For index/tuning help, follow these directions.[/url] |Tally Tables[/url]

    Twitter: @AnyWayDBA

  • Well here's how I solved it.

    First, I assigned rank to the saledate so that cumulative totals were not against randomly ordered dates, then I inserted results into temp table, then I used the recursive query template Alan provided.

    I have yet to be the one to ever come up with the best way. Please take a look see and show me more elegant way.

    select

    RANK() over (order by saledate) as rankOrder

    , saledate

    , saleprice

    into #temp

    from sales;

    select * from #temp;

    ;WITH CTE (rankOrder, SaleDate, [SalePrice], [Running Total])

    AS

    (

    SELECTrankOrder,

    SaleDate,

    [SalePrice],

    [SalePrice]

    FROM #temp

    WHERE rankOrder = 1

    UNION ALL

    SELECTa.rankOrder,

    a.SaleDate,

    a.[SalePrice],

    CTE.[Running Total] + a.[SalePrice]

    FROM CTE

    JOIN #temp a ON CTE.rankOrder + 1 = a.rankOrder

    )

    SELECT * FROM CTE

    OPTION (MAXRECURSION 0)

    GO

    --Quote me

  • polkadot (8/2/2012)


    Well here's how I solved it.

    First, I assigned rank to the saledate so that cumulative totals were not against randomly ordered dates, then I inserted results into temp table, then I used the recursive query template Alan provided.

    I have yet to be the one to ever come up with the best way. Please take a look see and show me more elegant way.

    select

    RANK() over (order by saledate) as rankOrder

    , saledate

    , saleprice

    into #temp

    from sales;

    select * from #temp;

    ;WITH CTE (rankOrder, SaleDate, [SalePrice], [Running Total])

    AS

    (

    SELECTrankOrder,

    SaleDate,

    [SalePrice],

    [SalePrice]

    FROM #temp

    WHERE rankOrder = 1

    UNION ALL

    SELECTa.rankOrder,

    a.SaleDate,

    a.[SalePrice],

    CTE.[Running Total] + a.[SalePrice]

    FROM CTE

    JOIN #temp a ON CTE.rankOrder + 1 = a.rankOrder

    )

    SELECT * FROM CTE

    OPTION (MAXRECURSION 0)

    GO

    Looks good to me. Put a unique clustered index on #temp on rankOrder to make it super fast.

    “Write the query the simplest way. If through testing it becomes clear that the performance is inadequate, consider alternative query forms.” - Gail Shaw

    For fast, accurate and documented assistance in answering your questions, please read this article.
    Understanding and using APPLY, (I) and (II) Paul White
    Hidden RBAR: Triangular Joins / The "Numbers" or "Tally" Table: What it is and how it replaces a loop Jeff Moden

Viewing 15 posts - 1 through 15 (of 16 total)

You must be logged in to reply to this topic. Login to reply