Find Row Number Based on Column Information

  • Hey Guys,

    I'm trying to find the ItemCode of the TreeType 'S' Above the Line that I'm running the query against.

    Here is the Table:

    VisOrderItemCodeTreeType

    0PA3922U-1ARA N

    1MULTI-DOCK-BUNDLE1+ S

    2PA3934U-1PRP I

    3PA3922U-1ARA I

    4PL10436401 I

    5PL10436401-10pk+ S

    6PL10436401 I

    7MULTI-DOCK-BUNDLE3+S

    8PA3934U-1PRP I

    9PA3956U-1PRP I

    10PL10436401 I

    11PA3922U-1ARA I

    12PA1495U-1TWC I

    13PA3945U-1EAB I

    14PL10436401-2PK+ S

    15PL10436401 I

    16920-003594 N

    The Resulting Code for PA3934U-1PRP on visorder 2 Should be MULTI-DOCK-BUNDLE1+ while being run against visorder 8 should be MULTI-DOCK-BUNDLE3+.

    Running PA3922U-1ARA from visOrder 3 Should also return MULTI-DOCK-BUNDLE1+ Etc.

    And running against a line with treetype 'S' OR 'N' Should not return anything.

    Thanks for your help.

  • I am pretty sure of what you are looking for. Can you take a few minutes to read the article found in my signature about best practices when posting questions? To offer much assistance we need ddl and sample data to work with and that article explains how to gather that information and post it in a readily consumable format.

    _______________________________________________________________

    Need help? Help us help you.

    Read the article at http://www.sqlservercentral.com/articles/Best+Practices/61537/ for best practices on asking questions.

    Need to split a string? Try Jeff Modens splitter http://www.sqlservercentral.com/articles/Tally+Table/72993/.

    Cross Tabs and Pivots, Part 1 – Converting Rows to Columns - http://www.sqlservercentral.com/articles/T-SQL/63681/
    Cross Tabs and Pivots, Part 2 - Dynamic Cross Tabs - http://www.sqlservercentral.com/articles/Crosstab/65048/
    Understanding and Using APPLY (Part 1) - http://www.sqlservercentral.com/articles/APPLY/69953/
    Understanding and Using APPLY (Part 2) - http://www.sqlservercentral.com/articles/APPLY/69954/

  • Thanks Sean,

    Please tell me if this is correct:

    IF OBJECT_ID('TempDB..#tTestTB') IS NOT NULL

    DROP TABLE #tTestTB

    CREATE TABLE #tTestTB(

    [VisOrder] [Int] NULL,

    [ItemCode] [varchar](25) NULL,

    [TreeType] [varchar] (1) NULL

    )

    INSERT INTO #tTestTB ( VisOrder,ItemCode,TreeType) VALUES ( 0,'PA3922U-1ARA','N')

    INSERT INTO #tTestTB ( VisOrder,ItemCode,TreeType) VALUES ( 1, 'MULTI-DOCK-BUNDLE1+','S')

    INSERT INTO #tTestTB ( VisOrder,ItemCode,TreeType) VALUES ( 2, 'PA3934U-1PRP','I')

    INSERT INTO #tTestTB ( VisOrder,ItemCode,TreeType) VALUES ( 3, 'PA3922U-1ARA','I')

    INSERT INTO #tTestTB ( VisOrder,ItemCode,TreeType) VALUES ( 4, 'PL10436401','I')

    INSERT INTO #tTestTB ( VisOrder,ItemCode,TreeType) VALUES ( 5, 'PL10436401-10pk+','S')

    INSERT INTO #tTestTB ( VisOrder,ItemCode,TreeType) VALUES ( 6, 'PL10436401','I')

    INSERT INTO #tTestTB ( VisOrder,ItemCode,TreeType) VALUES ( 7, 'MULTI-DOCK-BUNDLE3+','S')

    INSERT INTO #tTestTB ( VisOrder,ItemCode,TreeType) VALUES ( 8, 'PA3934U-1PRP','I')

    INSERT INTO #tTestTB ( VisOrder,ItemCode,TreeType) VALUES ( 9, 'PA3956U-1PRP','I')

    INSERT INTO #tTestTB ( VisOrder,ItemCode,TreeType) VALUES ( 10, 'PL10436401','I')

    INSERT INTO #tTestTB ( VisOrder,ItemCode,TreeType) VALUES ( 11, 'PA3922U-1ARA','I')

    INSERT INTO #tTestTB ( VisOrder,ItemCode,TreeType) VALUES ( 12, 'PA1495U-1TWC','I')

    INSERT INTO #tTestTB ( VisOrder,ItemCode,TreeType) VALUES ( 13, 'PA3945U-1EAB','I')

    INSERT INTO #tTestTB ( VisOrder,ItemCode,TreeType) VALUES ( 14, 'PL10436401-2PK+','S')

    INSERT INTO #tTestTB ( VisOrder,ItemCode,TreeType) VALUES ( 15, 'PL10436401','I')

    INSERT INTO #tTestTB ( VisOrder,ItemCode,TreeType) VALUES ( 16, '920-003594','N')

    SELECT * FROM #tTestTB

    DROP TABLE #tTestTB

    My Desire is to run this on a line by line basis.

    When run against line 0 the result would be blank

    Same for line 1

    Line 2 - 4 would return 'MULTI-DOCK-BUNDLE1+'

    Line 5 is blank

    Line 6 Returns 'PL10436401-10pk+' despite line 4 containing the same information

    Thank you for your help

  • DECLARE @ID INT = 2

    SELECT TOP 1 * FROM #tTestTB

    WHERE VisOrder < @ID AND TreeType = 'S'

    AND EXISTS(SELECT * FROM #tTestTB WHERE VisOrder = @ID AND TreeType <> 'S')

    ORDER BY VisOrder DESC


    Alex Suprun

  • Thanks for the details. Makes this kind of thing a lot easier!!!

    Something like this?

    SELECT t.*, isnull(x.ItemCode, '') as ItemCode

    FROM #tTestTB t

    outer apply(select top 1 ItemCode as ItemCode from #tTestTB t2 where t2.TreeType = 'S' and t2.VisOrder < t.VisOrder order by VisOrder desc) x

    _______________________________________________________________

    Need help? Help us help you.

    Read the article at http://www.sqlservercentral.com/articles/Best+Practices/61537/ for best practices on asking questions.

    Need to split a string? Try Jeff Modens splitter http://www.sqlservercentral.com/articles/Tally+Table/72993/.

    Cross Tabs and Pivots, Part 1 – Converting Rows to Columns - http://www.sqlservercentral.com/articles/T-SQL/63681/
    Cross Tabs and Pivots, Part 2 - Dynamic Cross Tabs - http://www.sqlservercentral.com/articles/Crosstab/65048/
    Understanding and Using APPLY (Part 1) - http://www.sqlservercentral.com/articles/APPLY/69953/
    Understanding and Using APPLY (Part 2) - http://www.sqlservercentral.com/articles/APPLY/69954/

  • Thanks. I really appreciate your help.

  • I like Sean's solution and got to wondering whether a subquery would work as well:

    SELECT t.*, isnull((

    select top 1 ItemCode as ItemCode

    from #tTestTB t2

    where t2.TreeType = 'S' and t2.VisOrder < t.VisOrder

    order by VisOrder desc

    ), '') as ItemCode

    FROM #tTestTB t

    So I tried a small test harness:

    IF OBJECT_ID('TempDB..#tTestTB') IS NOT NULL

    DROP TABLE #tTestTB

    CREATE TABLE #tTestTB(

    [VisOrder] [Int] IDENTITY (0,1) NOT NULL,

    [ItemCode] [varchar](25) NULL,

    [TreeType] [varchar] (1) NULL

    )

    SET NOCOUNT ON

    INSERT INTO #tTestTB ( ItemCode,TreeType) VALUES ( 'PA3922U-1ARA','N')

    INSERT INTO #tTestTB ( ItemCode,TreeType) VALUES ( 'MULTI-DOCK-BUNDLE1+','S')

    INSERT INTO #tTestTB ( ItemCode,TreeType) VALUES ( 'PA3934U-1PRP','I')

    INSERT INTO #tTestTB ( ItemCode,TreeType) VALUES ( 'PA3922U-1ARA','I')

    INSERT INTO #tTestTB ( ItemCode,TreeType) VALUES ( 'PL10436401','I')

    INSERT INTO #tTestTB ( ItemCode,TreeType) VALUES ( 'PL10436401-10pk+','S')

    INSERT INTO #tTestTB ( ItemCode,TreeType) VALUES ( 'PL10436401','I')

    INSERT INTO #tTestTB ( ItemCode,TreeType) VALUES ( 'MULTI-DOCK-BUNDLE3+','S')

    INSERT INTO #tTestTB ( ItemCode,TreeType) VALUES ( 'PA3934U-1PRP','I')

    INSERT INTO #tTestTB ( ItemCode,TreeType) VALUES ( 'PA3956U-1PRP','I')

    INSERT INTO #tTestTB ( ItemCode,TreeType) VALUES ( 'PL10436401','I')

    INSERT INTO #tTestTB ( ItemCode,TreeType) VALUES ( 'PA3922U-1ARA','I')

    INSERT INTO #tTestTB ( ItemCode,TreeType) VALUES ( 'PA1495U-1TWC','I')

    INSERT INTO #tTestTB ( ItemCode,TreeType) VALUES ( 'PA3945U-1EAB','I')

    INSERT INTO #tTestTB ( ItemCode,TreeType) VALUES ( 'PL10436401-2PK+','S')

    INSERT INTO #tTestTB ( ItemCode,TreeType) VALUES ( 'PL10436401','I')

    INSERT INTO #tTestTB ( ItemCode,TreeType) VALUES ( '920-003594','N')

    ;WITH Tally(n) AS (

    SELECT TOP 1000 ROW_NUMBER() OVER (ORDER BY (SELECT NULL))

    FROM sys.all_columns a CROSS JOIN sys.all_columns b)

    INSERT INTO #tTestTB

    SELECT ItemCode + '-' + CAST(n AS VARCHAR(7))

    ,TreeType

    FROM #tTestTB

    CROSS APPLY Tally

    DECLARE @Other VARCHAR(25)

    PRINT 'Subquery'

    SET STATISTICS TIME ON

    SELECT @Other=isnull((

    select top 1 ItemCode as ItemCode

    from #tTestTB t2

    where t2.TreeType = 'S' and t2.VisOrder < t.VisOrder

    order by VisOrder desc

    ), '') --as ItemCode

    FROM #tTestTB t

    SET STATISTICS TIME OFF

    PRINT 'Outer Apply'

    SET STATISTICS TIME ON

    SELECT @Other=isnull(x.ItemCode, '') --as ItemCode

    FROM #tTestTB t

    outer apply(

    select top 1 ItemCode as ItemCode

    from #tTestTB t2

    where t2.TreeType = 'S' and t2.VisOrder < t.VisOrder

    order by VisOrder desc) x

    SET STATISTICS TIME OFF

    DROP TABLE #tTestTB

    And got these results:

    Subquery

    SQL Server Execution Times:

    CPU time = 17972 ms, elapsed time = 18181 ms.

    Outer Apply

    SQL Server Execution Times:

    CPU time = 18330 ms, elapsed time = 18699 ms.

    Over many runs, I think such close results would probably go back and forth. There is only a slight difference in the execution plans.

    Obviously I have too much time on my hands late this Friday afternoon. 😛


    My mantra: No loops! No CURSORs! No RBAR! Hoo-uh![/I]

    My thought question: Have you ever been told that your query runs too fast?

    My advice:
    INDEXing a poor-performing query is like putting sugar on cat food. Yeah, it probably tastes better but are you sure you want to eat it?
    The path of least resistance can be a slippery slope. Take care that fixing your fixes of fixes doesn't snowball and end up costing you more than fixing the root cause would have in the first place.

    Need to UNPIVOT? Why not CROSS APPLY VALUES instead?[/url]
    Since random numbers are too important to be left to chance, let's generate some![/url]
    Learn to understand recursive CTEs by example.[/url]
    [url url=http://www.sqlservercentral.com/articles/St

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

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