• Skip (7/4/2010)


    I just re-copied your sp and it is working like a charm. For the life of I don't know what I did to mess it up.

    The code does confuse me though. I am having a difficult time following the thought process. I hate to burden you, but if you have some time to explain the code a little, I'm sure I'd learn more about it. If not, I'll just tear it apart next week at the office.

    Thanks very much for your help MM. You're a real life saver.

    No problem....here goes

    CREATE PROC move_order @key INT,@line INT,@priority INT

    AS

    SET NOCOUNT ON;

    -- collect the existing data for the key

    DECLARE @old_priority INT,@old_line INT

    SELECT @old_priority=priority,@old_line=line FROM FPD_Schedule WHERE =@key

    -- move everything up on the line we are moving from

    -- move everything down on the line we are moving to

    -- move the specified order

    UPDATE FPD_Schedule

    So, this one update will take care of all three main categories of rows

    • Items in the line which originally held the order
    • Items in the line to which the order will move
    • The order which is moving

    First we can handle the order we are moving by checking for the supplied @key value in the key field and setting the required priority

    SET priority= CASE

    WHEN @key THEN @priority

    Next we handle the case where we are just changing priority on the same line:

    ELSE

    CASE

    WHEN @line=@old_line THEN priority +

    We need to either increment or decrement the priority by 1 for all orders which have a priority that lies between the original priority of the order we are moving and it's new priority.

    Suppose we move priority 4 to priority 2 then we need to adjust everything between priority 2 and 4

    1 2* 3* 4*

    This CASE statement finds orders in that priority range

    CASE

    WHEN priority BETWEEN @priority AND @old_priority

    OR priority BETWEEN @old_priority AND @priority THEN

    And this one says that is we are moving the order up the line then all other orders in the selected range must move down (+1) and vice versa (-1)

    (and if the priority of the selected order is not changing, then don't move anything (0))

    CASE

    WHEN @priority<@old_priority THEN 1

    WHEN @priority>@old_priority THEN -1

    ELSE 0

    END

    And this ELSE is for orders that are not affected by the change, so use an adjustment value of zero.

    ELSE 0

    END

    Next, we handle where the order is changing line.

    First, move the priority of orders on the old line up one.

    WHEN line=@old_line AND priority>@old_priority THEN priority-1

    Then move the orders on the new line down one.

    WHEN line=@line AND priority>=@priority THEN priority+1

    And any orders that are not affected by the order move keep their original priority....

    ELSE priority

    END

    END

    And finally, move the selected order to it's new line (even if that is the same as the old line - no harm done.)

    , line = CASE

    WHEN @key THEN @line

    ELSE [line]

    END

    And select only the lines we are affecting...

    WHERE line=@line OR line=@old_line

    You could also extend the where clause to be more selective by only selecting records from each line that will be affected (using the priority range) but it's late and I don't have time to do that now....

    MM



    select geometry::STGeomFromWKB(0x0106000000020000000103000000010000000B0000001000000000000840000000000000003DD8CCCCCCCCCC0840000000000000003DD8CCCCCCCCCC08408014AE47E17AFC3F040000000000104000CDCCCCCCCCEC3F9C999999999913408014AE47E17AFC3F9C99999999991340000000000000003D0000000000001440000000000000003D000000000000144000000000000000400400000000001040000000000000F03F100000000000084000000000000000401000000000000840000000000000003D0103000000010000000B000000000000000000143D000000000000003D009E99999999B93F000000000000003D009E99999999B93F8014AE47E17AFC3F400000000000F03F00CDCCCCCCCCEC3FA06666666666FE3F8014AE47E17AFC3FA06666666666FE3F000000000000003D1800000000000040000000000000003D18000000000000400000000000000040400000000000F03F000000000000F03F000000000000143D0000000000000040000000000000143D000000000000003D, 0);

  • Forum Etiquette: How to post Reporting Services problems
  • [/url]
  • Forum Etiquette: How to post data/code on a forum to get the best help - by Jeff Moden
  • [/url]
  • How to Post Performance Problems - by Gail Shaw
  • [/url]