Procedure to insert randomly selected data from same table, to bottom of that table

  • Hi all,

    I have thousands of items skus like below. only chose first 7.

    Item NumberDescriptionlinesunitslengthwidthheightweightData SourceActiveCurrent

    1122626910Picks11

    31155100Picks11

    65850501300Picks11

    75519731000Picks11

    8331825330Picks11

    93355600Picks11

    10122330501450Picks11

    65850501300Picks10

    93355600Picks10

    I need a function that will look at the current dataset where Current = 1, then copies a random row, adds to bottom of dataset and replaces Current to 0.

    So if i want to add two new random products to the product range, i change the number to 2, then it randomly selects 2 from list and replaces 1 with 0, like the two red rows.

    the scale is around 200,000 current products and want to add 24,000 "new" randomly selected SKU to next years dataset, i dont know what the new skus will be but i can analysis what affect the increase in product range will have.

    thanks in advanced

  • I've simplified your product table a little to concoct this example because I'm too lazy to build the requisite DDL and consumable sample data exactly as you've shown.

    DECLARE @OldProducts TABLE

    (

    ProductID INT IDENTITY

    ,[Current] INT

    );

    DECLARE @NewProducts TABLE

    (

    ProductID INT

    ,[Current] INT

    );

    WITH Tally (n) AS

    (

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

    FROM sys.all_columns

    )

    INSERT INTO @OldProducts

    SELECT 1

    FROM Tally;

    SELECT *

    FROM @OldProducts;

    WITH TwoProducts AS

    (

    SELECT TOP (2) ProductID, [Current]

    FROM @OldProducts

    WHERE [Current] = 1

    ORDER BY NEWID()

    )

    UPDATE TwoProducts

    SET [Current] = 0

    OUTPUT INSERTED.ProductID, 1

    INTO @NewProducts;

    SELECT *

    FROM @OldProducts;

    SELECT *

    FROM @NewProducts;

    If this doesn't give you the idea then let me know.


    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

  • thanks for that dwain.c.

    that helped a lot.

    manage to work on it and also add a few things to your solution.

    much appreciated.

Viewing 3 posts - 1 through 2 (of 2 total)

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