Confused with "Order by" output

  • declare @temp table ( id int , phn int)

    insert into @temp

    select 1 , 16454 UNION SELECT

    2 , 5485 UNION SELECT

    3 , 16454 UNION SELECT

    4 , 11542 UNION SELECT

    5 , 16454 UNION SELECT

    6 , 5485

    SELECT * FROM @temp T1

    ORDER BY (SELECT COUNT(*) FROM @temp T2 WHERE T1.Phn = T2.Phn) DESC, ID ASC

    whats the output of SELECT COUNT(*) FROM @temp T2 WHERE T1.Phn = T2.Phn

    -------Bhuvnesh----------
    I work only to learn Sql Server...though my company pays me for getting their stuff done;-)

  • SELECT *, (SELECT COUNT(*) FROM @temp T2 WHERE T1.Phn = T2.Phn)

    FROM @temp T1

    ORDER BY (SELECT COUNT(*) FROM @temp T2 WHERE T1.Phn = T2.Phn) DESC, ID ASC

    “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

  • thanks

    -------Bhuvnesh----------
    I work only to learn Sql Server...though my company pays me for getting their stuff done;-)

  • Without duplicating the expression:

    DECLARE @temp

    TABLE (

    id INTEGER NOT NULL,

    phn INTEGER NOT NULL

    );

    INSERT @temp

    (id, phn)

    SELECT 1 , 16454 UNION ALL

    SELECT 2 , 05485 UNION ALL

    SELECT 3 , 16454 UNION ALL

    SELECT 4 , 11542 UNION ALL

    SELECT 5 , 16454 UNION ALL

    SELECT 6 , 05485;

    SELECT id, phn, phn_count = COUNT(*) OVER (PARTITION BY phn)

    FROM @temp T1

    ORDER BY

    phn_count DESC,

    ID ASC;

    Or, removing it from the SELECT altogether:

    SELECT T1.id,

    T1.phn

    FROM @temp T1

    CROSS

    APPLY (

    SELECT COUNT(*) OVER (PARTITION BY phn)

    ) DV (phn_count)

    ORDER BY

    DV.phn_count DESC,

    T1.id ASC;

Viewing 4 posts - 1 through 4 (of 4 total)

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