Generating Complex SQL Code

  • Hi All,

    we have a situation where we need to split the data in one row and insert it to multiple rows based on the data set Exiting:

    Example

    Table 1:

    School Class Scholarship

    DONBOS 10th 1000

    Table 2:

    School Class Name Credits

    DONBOS 10th Ajay 20

    DONBOS 10th Ramesh 12

    DONBOS 10th Bobby 15

    DONBOS 10th Giri 10

    Result:

    School class name Scholarship

    DONBOS 10th Ajay 1000 * 20 / (20+12+15+10)

    DONBOS 10th Ramesh 1000 * 12 / (20+12+15+10)

    DONBOS 10th Bobby 1000 * 15 / (20+12+15+10)

    DONBOS 10th Giri 1000 * 10 / (20+12+15+10)

    the process can be built as Function / procedure, please need inputs.

  • With 48 points to your credit, I'd think you should know that the forum helpers would be much obliged if you could provide DDL and consumable sample data like this:

    CREATE TABLE #Table1

    (School VARCHAR(10)

    ,Class VARCHAR(10)

    ,Scholarship MONEY)

    INSERT INTO #Table1 SELECT 'DONBOS','10th',1000

    CREATE TABLE #Table2

    (School VARCHAR(10)

    ,Class VARCHAR(10)

    ,Name VARCHAR(10)

    ,Credits INT)

    INSERT INTO #Table2

    SELECT 'DONBOS','10th','Ajay',20 UNION ALL SELECT 'DONBOS','10th','Ramesh',12

    UNION ALL SELECT 'DONBOS','10th','Bobby',15 UNION ALL SELECT 'DONBOS','10th','Giri',10

    So here's a sample solution to get you started:

    SELECT a.School, a.Class, a.Name

    ,AllocatedAmt=ROUND((a.Credits * b.Scholarship) /

    SUM(a.Credits) OVER (PARTITION BY a.School, a.Class), 0)

    FROM #Table2 a

    INNER JOIN #Table1 b ON a.School = b.School AND a.Class = b.Class

    DROP TABLE #Table1

    DROP TABLE #Table2

    Now it just so happens that the sum of the allocated and rounded scholarship amounts in this example adds up exactly to 1000. But that isn't always going to be the case. So when it doesn't you'll need to use a "fudge rounding" technique to force the total of the allocated amounts to equal the total.

    Read this article to understand how to do that:

    Financial Rounding of Allocations[/url]


    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 2 posts - 1 through 1 (of 1 total)

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