Stored Proc to split data in two

  • Hey all,

    I have a stored proc. It does what i want it to - but it seems over complex and a little slow for my liking.

    Its used in reporting services to split a menu between a left and right hand side - and if the user has an odd number of menu items the left side gets the extra one. So if there is 10 it will be a 5,5 split. if its 9 it would be a 5,4 split.

    Basically the data is in here:

    SELECT DISTINCT

    Report_Group_Code

    ,Report_Group_Name

    FROModr.tbl_ExpandedPermissions

    where username = 'me'

    order by Report_Group_Name

    So how do i get a column that the says either left or right. So if there were ten the top 5 would say left and the bottom 5 right. If there were 9 then the top 5 would say left and the bottom 5 would say right. The distinct is a required element.

    So i have this :

    Create PROC [ODR].[SP_MainMenu]

    @currentuser VARCHAR(100)

    ,@side VARCHAR(5)

    AS

    WITHLIST

    AS ( SELECT DISTINCT

    Report_Group_Code

    ,Report_Group_Name

    FROModr.tbl_ExpandedPermissions

    WHEREADLogon = @currentuser

    )

    SELECTDATA.Report_Group_Code

    ,DATA.Report_Group_Name

    ,ODRImage

    FROM( SELECTReport_Group_Code

    ,Report_Group_Name

    ,ROW_NUMBER() OVER ( ORDER BY Report_Group_Name ) AS rownum

    FROMlist

    ) DATA

    INNER JOIN

    ODR.tbl_ReportGroups

    ON DATA.Report_Group_Code = ODR.tbl_ReportGroups.Report_Group_Code

    WHERECASE WHEN rownum <= ( SELECTCAST(COUNT(*) AS NUMERIC(5, 2))

    FROMList

    ) / 2 + 0.5 THEN 'left'

    ELSE 'right'

    END = @side

    GO

    [/Code]

    Can anyone think of a better way?

    Dan

  • The easiest way would be to use a row_number, and odd rows on the left, even on the right. Thus, in a 3-element list: 1 & 3 on the left, 2 on the right. 5-elements: 1,3,5 on left, 2&4 on right. Would get you the right number per side, but wouldn't be strictly alphabetical. Does that work? Would definitely be efficient.

    Alternatively, something like this:

    DECLARE @MaxNumber INT = 10;

    IF OBJECT_ID(N'tempdb..#T') IS NOT NULL

    DROP TABLE #T;

    SELECT Number

    INTO #T

    FROM dbo.Numbers

    WHERE Number BETWEEN 1 AND @MaxNumber;

    WITH Rt

    AS (SELECT TOP 50 PERCENT

    Number

    FROM #T

    ORDER BY Number),

    Lt

    AS (SELECT Number

    FROM #T

    EXCEPT

    SELECT Number

    FROM Rt)

    SELECT Number,

    'Right' AS Col

    FROM Rt

    UNION ALL

    SELECT Number,

    'Left' AS Col

    FROM Lt

    ORDER BY Number;

    Modify to fit your actual table, then test for performance. Can't say it'll do better than the current query against your actual data, it's just a possible alternative solution.

    - Gus "GSquared", RSVP, OODA, MAP, NMVP, FAQ, SAT, SQL, DNA, RNA, UOI, IOU, AM, PM, AD, BC, BCE, USA, UN, CF, ROFL, LOL, ETC
    Property of The Thread

    "Nobody knows the age of the human race, but everyone agrees it's old enough to know better." - Anon

  • here's an example i wrote that splits sys.tables into five columns;

    i hope it's obvious how you could apply the same logic to your data.

    WITH

    baseCTE AS

    (

    SELECT

    (ROW_NUMBER() OVER (ORDER BY Name)-1)/5+1 AS RW,

    (ROW_NUMBER() OVER (ORDER BY Name)-1)%5+1 AS CL,

    Name

    FROM sys.tables

    )

    SELECT MAX(CASE WHEN CL = 1 THEN Name ELSE '' END) AS Col1TableName,

    MAX(CASE WHEN CL = 2 THEN Name ELSE '' END) AS Col2TableName,

    MAX(CASE WHEN CL = 3 THEN Name ELSE '' END) AS Col3TableName,

    MAX(CASE WHEN CL = 4 THEN Name ELSE '' END) AS Col4TableName,

    MAX(CASE WHEN CL = 5 THEN Name ELSE '' END) AS Col5TableName

    FROM baseCTE

    GROUP BY RW

    ORDER BY RW

    Lowell


    --help us help you! If you post a question, make sure you include a CREATE TABLE... statement and INSERT INTO... statement into that table to give the volunteers here representative data. with your description of the problem, we can provide a tested, verifiable solution to your question! asking the question the right way gets you a tested answer the fastest way possible!

  • Try NTILE().

    Drew

    J. Drew Allen
    Business Intelligence Analyst
    Philadelphia, PA

  • All valid options - many thanks.

    I do like the look of NTILE though. New function for me..... never even heard of it, but it seems to do the job nicely.

    Thanks all

    Dan

  • drew.allen (8/7/2012)


    Try NTILE().

    Drew

    Cool! Somehow, I missed that one in the ranking functions. Very nice.

    - Gus "GSquared", RSVP, OODA, MAP, NMVP, FAQ, SAT, SQL, DNA, RNA, UOI, IOU, AM, PM, AD, BC, BCE, USA, UN, CF, ROFL, LOL, ETC
    Property of The Thread

    "Nobody knows the age of the human race, but everyone agrees it's old enough to know better." - Anon

Viewing 6 posts - 1 through 5 (of 5 total)

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