The T-SQL Quiz

  • Comments posted here are about the content posted at http://www.sqlservercentral.com/columnists/gFritchey/2973.asp

    "The credit belongs to the man who is actually in the arena, whose face is marred by dust and sweat and blood"
    - Theodore Roosevelt

    Author of:
    SQL Server Execution Plans
    SQL Server Query Performance Tuning

  • It's funny nobody, even author, mentioned an obvious solution:

    SELECT

    ISNULL(

    NULLIF(

    CASE WHEN Number % 3 = 0 THEN 'Bizz' ELSE '' END +

    CASE WHEN Number % 5 = 0 THEN 'Buzz' ELSE '' END

    , '')

    , CAST(Number AS nvarchar(10) )

    )

    from master.dbo.spt_values

    where type = 'P' AND Number > 0 AND Number < 100

    order by Number

    When you're doing databases you should not reference the same value twice in your query.

    And not dropping table Nums is not bad.

    Not having it before is bad.

    And the way it's populated in the example is terribly wrong.

    _____________
    Code for TallyGenerator

  • Let's use a little logic. Any number divisible by both 3 and 5 will be divisible by 15. You don't need to check for both 3 & 5, you simply need to check for 15.

    Declare @Counter int

    Set @Counter = 1

    While @Counter <= 100

      Begin

         Print Case When @Counter % 15 = 0 Then 'BizzBuzz'

               When @Counter % 5 = 0 Then 'Buzz'

               When @Counter % 3 = 0 Then 'Bizz'

               Else Str(@Counter)

         End

         Set @Counter = @Counter + 1

      End

     


    My blog: SQL Soldier[/url]
    SQL Server Best Practices:
    SQL Server Best Practices
    Twitter: @SQLSoldier
    My book: Pro SQL Server 2008 Mirroring[/url]
    Microsoft Certified Master: SQL Server, Data Platform MVP
    Database Engineer at BlueMountain Capital Management[/url]

  • --Here's a set based solution.

    Declare @n Table (i integer Not Null, Primary Key(i))

    Insert @n

    Select 0 as i Union All

    Select 1 Union All

    Select 2 Union All

    Select 3 Union All

    Select 4 Union All

    Select 5 Union All

    Select 6 Union All

    Select 7 Union All

    Select 8 Union All

    Select 9

    Select

     x,

     Case When x % 3 = 0 Then 'Bizz' Else '' End + Case When x % 5 = 0 Then 'Buzz'  Else '' End as tag

    From

     (Select

      tens.i * 10 + units.i + 1 as x

     From

      @n units

     Cross Join

      @n tens

    &nbsp as A

    Order By

     x

     

     

  • I'm afraid you wouldn't make it to the 2nd round. If you're interviewing for a job, you're not going to already have that table in there. Your query would return an error, and when you tell them that it's their fault for not having the table there already, your interview is over.


    My blog: SQL Soldier[/url]
    SQL Server Best Practices:
    SQL Server Best Practices
    Twitter: @SQLSoldier
    My book: Pro SQL Server 2008 Mirroring[/url]
    Microsoft Certified Master: SQL Server, Data Platform MVP
    Database Engineer at BlueMountain Capital Management[/url]

  • Interesting example, but fails to follow the directions. The directions is to substitute the value with the string, not provide it as a second value.


    My blog: SQL Soldier[/url]
    SQL Server Best Practices:
    SQL Server Best Practices
    Twitter: @SQLSoldier
    My book: Pro SQL Server 2008 Mirroring[/url]
    Microsoft Certified Master: SQL Server, Data Platform MVP
    Database Engineer at BlueMountain Capital Management[/url]

  • 1st of all - my query DOES NOT return an error.

    Try before you say.

    2nd, if I would include new table into my solution I would separate CREATE TABLE statement from the solution and prefix it with NOT EXIST check.

    By the way, my solution takes less than 3ms. At least SQL Server cannot catch that time interval.

    _____________
    Code for TallyGenerator

  • BTW, the question itself is so "front end"!

    The whole nature of a professional database developer protests against mixing different datatypes in one column.

    _____________
    Code for TallyGenerator

  • Just a slight modification to one of the examples:

    WITH

    Nbrs(n) AS (

        SELECT 1

        UNION ALL

        SELECT 1 + n FROM Nbrs WHERE n < 100)

    SELECT CASE WHEN n%15 = 0 THEN 'BizzBuzz'

        WHEN n%3 = 0 THEN 'Bizz'

        WHEN n%5 = 0 THEN 'Buzz'

        ELSE CAST(n AS VARCHAR(8))

        END

    FROM Nbrs

    Saying n is divisible by 3 and n is divisible by 5 is just another way of saying n is divisible by 15.  I liked this option best, and my solution would have been similar, although my first thought would have been to create a Numbers table  first, especially if I planned on doing this type of operation often -- although this method with the CTE works well too

  • (This is going to sound like a bit of a rant... and it probably is.   Sorry... )

    Although Grant mentioned it in the end, there's a bit of irony in the article in that I wouldn't hire anyone who wrote such code as that shown in the article (simple as it was). 

    Folks, getting the correct answer isn't enough... you have to do it with performance and scalability in mind and you must keep both in mind all the time.  Add code readability to that, as well.

    Let's bump up the stakes a bit... lets use 1,000,000 rows for the same code...

    First, Grant's code doesn't work, as is... it dies at 1,000 so it's NOT SCALABLE.  He wouldn't make it past the first round because he didn't write the code to be scalable despite what the requirements said (100 rows).  Here's the error his code produces...

    Server: Msg 245, Level 16, State 1, Line 7

    Syntax error converting the varchar value '*' to a column of data type int.

    Det's first attempt has a second fault that Grant missed altogether... it has a GO in it that just isn't required and causes the code to fail if you declare any timing variables before it.  He also should have done a SET NOCOUNT ON to keep from printing a million (1 row(s) affected) messages which really slowed his code down.

    Det's second attempt isn't even worth mentioning because it would produce a million single row result sets, as Grant stated.

    Let's look at a couple of other things... Scott made the mistake of formatting the output.  For the most part, formatting the output in SQL is a Bozo-No-No.  That type of formatting should be done in the app, if there is one.

    Except for Det's first attempt, everyone took it at face value that the output should be printed instead of properly returned as a single usable result set.  The requirements never said Print anywhere... it said Count.  Ya gotta think about being able to use the output from any query as a single usable result set all the time.

    John Chapman has the right idea but it'll take a bit more code to reach a million rows.  At least he tried a setbased solution! (Michael Valentine Jones has a dandy function that operates similar to John's performance enabled code but I can't find the URL for it).

    Serqiy certainly has the right idea, but again, no scalability for the future.

    I can't test the CTE solution because I don't have 2k5, but I'll just bet it's fast.

    And... everyone failed the "test" because no one included any documentation!

    After repairing Grant's code, here's the results from the million row tests (not truly scalable but certainly more than 100 rows )...

    Grant's code took        203.626 seconds and pegged my single CPU the whole time.

    Chris' code took          193.640 seconds and pegged my single CPU the whole time.

    Det's first snippet took 286.156 seconds and pegged my single CPU the whole time.

    Scott's code took        285.296 seconds and pegged my single CPU the whole time.

    Those are some pretty hefty times for only a million rows.  So... how would I do this?  Like this, interview or not... would be even faster with MVJ's function...

    /*************************************************************

     Test code requirements:

     1. Count from 1 to 100. (modified to use 1 million rows)

     2. For each number evenly divisible by 3, substitute 'Bizz'.

     3. For each number evenly divisible by 5, substitute 'Buzz'.

     4. For each number divisible by both substitute 'BizzBuzz'

     Revision History:

     Rev 00 - 05/28/2007 - Jeff Moden - Initial creation/unit test.

                         - Deviation: Added duration counter to

                           measure run duration.

     Rev 01 - 05/28/2007 - Jeff Moden - Modified to use 1 million

                           rows for performance/scalability test.

    *************************************************************/

    --===== Declare and start the duration timer

    DECLARE @StartTime DATETIME

        SET @StartTime = GETDATE()

    --===== Declare and set a variable to control the number of

         -- rows created.

    DECLARE @DesiredRowCount INT

        SET @DesiredRowCount = 1000000

    --===== Disable the auto-display of rowcounts for appearance

         -- and speed

        SET NOCOUNT ON

    --===== If the scratchpad table already exists, drop it

         -- Note this is just so you can rerun the test.

         IF OBJECT_ID('TempDB..#Nums','U') IS NOT NULL

            DROP TABLE #Nums

    --===== Limit the number of rows to be built

        SET ROWCOUNT @DesiredRowCount

    --===== Create and populate the table on the fly

      SELECT IDENTITY(INT,1,1) AS RowNum,

             CAST(NULL AS VARCHAR(10)) AS DesiredResult

       INTO #Nums

       FROM Master.dbo.SysColumns sc1 WITH (NOLOCK),

            Master.dbo.SysColumns sc2 WITH (NOLOCK)

    --===== Restore the number of rows to return to normal

         -- Note: Can replace with TOP @variable in SQL 2k5

        SET ROWCOUNT 0

    --===== Produce the desired results according to the

         -- requirements in the code header.  Avoids concatenation which

         -- would cause the code to run a second slower...

     SELECT CASE

                 WHEN RowNum % 15 = 0 THEN 'BizzBuzz' --Divisible by 15

                 WHEN RowNum %  3 = 0 THEN 'Bizz'     --Divisible by 3

                 WHEN RowNum %  5 = 0 THEN 'Buzz'     --Divisible by 5

                 ELSE CAST(RowNum AS VARCHAR(10))

            END AS DesiredResult

       FROM #Nums

      ORDER BY RowNum

    --===== Display the run duration (not part of result set)

      PRINT DATEDIFF(ms,@StartTime,GETDATE())

    ... the total run time is 8.610 seconds (NOT a type-o... less than 9 seconds and a good 20 times (2000%) faster than the fastest loop code) and, yes, it pegged my single CPU... but what would you rather have... a pegged CPU for 3+ minutes or 9 seconds?  Speed is important and RBAR (pronounced "ree-bar" and is a "Modenism" for "Row By Agonizing Row") in the form of single row loops and cursors should be avoided at all cost.  There are a small handful of exceptions for loops in functions, but for the most part, they are an evil thing.

    --Jeff Moden


    RBAR is pronounced "ree-bar" and is a "Modenism" for Row-By-Agonizing-Row.
    First step towards the paradigm shift of writing Set Based code:
    ________Stop thinking about what you want to do to a ROW... think, instead, of what you want to do to a COLUMN.

    Change is inevitable... Change for the better is not.


    Helpful Links:
    How to post code problems
    How to Post Performance Problems
    Create a Tally Function (fnTally)

  • I happened to have a UDF in my test box that returns a set of numbers, so it was very easy for me to put this together:

    select

    case when n % 3 = 0 and n % 5 = 0 then 'BizzBuzz' when n % 3 = 0 then 'Bizz' when n % 5 = 0 then 'Buzz' else cast(n as varchar(10)) end from Numbers(1,100)

     

    The UDF is something I found on Mr Steve Kass's home page. In turn, he gives credit to Mr Itzik Ben-Gan.

    create function Numbers(

      @from as bigint,

      @to as bigint

    ) returns table with schemabinding as return

      with t0(n) as (

        select 1 union all select 1

     &nbsp, t1(n) as (

        select 1 from t0 as a, t0 as b

     &nbsp, t2(n) as (

        select 1 from t1 as a, t1 as b

     &nbsp, t3(n) as (

        select 1 from t2 as a, t2 as b

     &nbsp, t4(n) as (

        select 1 from t3 as a, t3 as b

     &nbsp, t5(n) as (

        select 1 from t4 as a, t4 as b

     &nbsp, Numbers(n) as (

        select row_number() over (order by n) as n

        from t5

     &nbsp

        select @from + n - 1 as n

        from Numbers

        where n <= @to - @from + 1

    Try it also with a million numbers. It is pretty fast!

  • Jeff, a little note:

    there was no requirement for proper commenting, there was a requirement for 2 min solution.

    Cannot say about anybody else, but my typing would not give me a chance to fit the time requirement if I would start typing comments.

    And for scalabale solution I would go with Numbers table as well, but for that request spt_values got more than enough numbers. So why waste time on it, if total number could be limited by some business logic.

    _____________
    Code for TallyGenerator

  • declare @ int set @=1while @<101begin print ISNULL(NULLIF(CASE WHEN @%3=0THEN'Fizz'ELSE''END+CASE WHEN @%5=0THEN'Buzz'ELSE''END,''),@)set @=@+1 end


    N 56°04'39.16"
    E 12°55'05.25"

  • More here

    http://www.sqlteam.com/forums/topic.asp?TOPIC_ID=79902&whichpage=1

     


    N 56°04'39.16"
    E 12°55'05.25"

  • Deadline missed, budget exceeded, client unhappy.

    The problem was simple, the solution was not. 

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

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