SQL Clone
SQLServerCentral is supported by Redgate
 
Log in  ::  Register  ::  Not logged in
 
 
 


How to get the correct Return_Amt from a table?


How to get the correct Return_Amt from a table?

Author
Message
David Looi
David Looi
Forum Newbie
Forum Newbie (2 reputation)Forum Newbie (2 reputation)Forum Newbie (2 reputation)Forum Newbie (2 reputation)Forum Newbie (2 reputation)Forum Newbie (2 reputation)Forum Newbie (2 reputation)Forum Newbie (2 reputation)

Group: General Forum Members
Points: 2 Visits: 17
Please can anyone help me?

Table Name: tableSTK
ItemID varchar(8)
ItemDesc varchar(100)
Price money

Table Name: tableABC
ItemID varchar(8)
ConditionAmt money
Return_Amt money

The ConditionAmt and Return_Amt in the tableABC can be some other values based on the ItemID.

Here is the sample with different values.

ItemID ItemDesc Price
04400110 A4 Paper 30.00
08800220 Bic Pen 5.0 20.00

ItemID ConditionAmt Return_Amt
04400110 100.00 28.50
04400110 200.00 27.00
04400110 300.00 25.50
08800220 50.00 19.00
08800220 80.00 18.00
08800220 150.00 15.00
08800220 200.00 14.00

I need a query to get the correct value from the Return_Amt based on the ConditionAmt of a total purchase amt on the particular ItemID.

Examples
A.
John have a total purchase amt of 105.00.
When he purchase ItemID 04400110 while total purchase amt is more than ConditionAmt 100.00 and below 200 and below 300 the Return_Amt is 28.50 as SellingPrice.

B.
John have a total purchase amt of 250.00.
When he purchase ItemID 04400110 while total purchase amt is more than ConditionAmt 200.00 and below 300 the Return_Amt is 27.00 as SellingPrice.

C.
John have a total purchase amt of 400.00.
When he purchase ItemID 04400110 while total purchase amt is more than ConditionAmt 300.00 the Return_Amt is 28.50 as SellingPrice.

D.
John have a total purchase amt of 50.00.
When he purchase ItemID 04400110 while total purchase amt is less than ConditionAmt 100.00 therefore the ItemID 04400110 Price 30.00 as SellingPrice.

E.
Mary have a total purchase amt of 95.00.
When she purchase ItemID 08800220 while total purchase amt is more than ConditionAmt 80.00 and below 150 and below 200 the Return_Amt is 18.00 as SellingPrice.

Thanks.
jwlooi
Kingston Dhasian
Kingston Dhasian
Hall of Fame
Hall of Fame (3.7K reputation)Hall of Fame (3.7K reputation)Hall of Fame (3.7K reputation)Hall of Fame (3.7K reputation)Hall of Fame (3.7K reputation)Hall of Fame (3.7K reputation)Hall of Fame (3.7K reputation)Hall of Fame (3.7K reputation)

Group: General Forum Members
Points: 3687 Visits: 5177
One of the ways to achieve it..

DECLARE   @tableSTK TABLE
(
ItemID VARCHAR(8),
ItemDesc VARCHAR(100),
Price MONEY
)

DECLARE @tableABC TABLE
(
ItemID VARCHAR(8),
ConditionAmt MONEY,
Return_Amt MONEY
)

INSERT @tableSTK
( ItemID, ItemDesc, Price )
SELECT '04400110', 'A4 Paper', 30.00 UNION ALL
SELECT '08800220', 'Bic Pen 5.0', 20.00

INSERT @tableABC
( ItemID, ConditionAmt, Return_Amt )
SELECT '04400110', 100.00, 28.50 UNION ALL
SELECT '04400110', 200.00, 27.00 UNION ALL
SELECT '04400110', 300.00, 25.50 UNION ALL
SELECT '08800220', 50.00, 19.00 UNION ALL
SELECT '08800220', 80.00, 18.00 UNION ALL
SELECT '08800220', 150.00, 15.00 UNION ALL
SELECT '08800220', 200.00, 14.00

DECLARE @ConditionAmt INT,
@ItemID VARCHAR(8)

SELECT @ConditionAmt = 95.00,
@ItemID = '08800220'

; WITH cte_table AS
(
SELECT ROW_NUMBER() OVER( PARTITION BY ItemID ORDER BY ConditionAmt ) AS RN, * FROM
(
SELECT ItemID, 0 AS ConditionAmt, Price
FROM @tableSTK
UNION ALL
SELECT ItemID, ConditionAmt, Return_Amt
FROM @tableABC
) AS T
)

SELECT T1.ItemID, T1.Price
FROM cte_table AS T1
LEFT JOIN cte_table AS T2 ON T1.ItemID = T2.ItemID AND T1.RN = T2.RN - 1
WHERE T1.ItemID = @ItemID AND T1.ConditionAmt <= @ConditionAmt AND ( T2.ConditionAmt > @ConditionAmt OR T2.ConditionAmt IS NULL )




Kingston Dhasian

How to post data/code on a forum to get the best help - Jeff Moden
http://www.sqlservercentral.com/articles/Best+Practices/61537/
David Looi
David Looi
Forum Newbie
Forum Newbie (2 reputation)Forum Newbie (2 reputation)Forum Newbie (2 reputation)Forum Newbie (2 reputation)Forum Newbie (2 reputation)Forum Newbie (2 reputation)Forum Newbie (2 reputation)Forum Newbie (2 reputation)

Group: General Forum Members
Points: 2 Visits: 17
WOW! Thanks for your help. It solve my problem.

jwlooi

Kingston Dhasian (9/11/2013)
One of the ways to achieve it..

DECLARE   @tableSTK TABLE
(
ItemID VARCHAR(8),
ItemDesc VARCHAR(100),
Price MONEY
)

DECLARE @tableABC TABLE
(
ItemID VARCHAR(8),
ConditionAmt MONEY,
Return_Amt MONEY
)

INSERT @tableSTK
( ItemID, ItemDesc, Price )
SELECT '04400110', 'A4 Paper', 30.00 UNION ALL
SELECT '08800220', 'Bic Pen 5.0', 20.00

INSERT @tableABC
( ItemID, ConditionAmt, Return_Amt )
SELECT '04400110', 100.00, 28.50 UNION ALL
SELECT '04400110', 200.00, 27.00 UNION ALL
SELECT '04400110', 300.00, 25.50 UNION ALL
SELECT '08800220', 50.00, 19.00 UNION ALL
SELECT '08800220', 80.00, 18.00 UNION ALL
SELECT '08800220', 150.00, 15.00 UNION ALL
SELECT '08800220', 200.00, 14.00

DECLARE @ConditionAmt INT,
@ItemID VARCHAR(8)

SELECT @ConditionAmt = 95.00,
@ItemID = '08800220'

; WITH cte_table AS
(
SELECT ROW_NUMBER() OVER( PARTITION BY ItemID ORDER BY ConditionAmt ) AS RN, * FROM
(
SELECT ItemID, 0 AS ConditionAmt, Price
FROM @tableSTK
UNION ALL
SELECT ItemID, ConditionAmt, Return_Amt
FROM @tableABC
) AS T
)

SELECT T1.ItemID, T1.Price
FROM cte_table AS T1
LEFT JOIN cte_table AS T2 ON T1.ItemID = T2.ItemID AND T1.RN = T2.RN - 1
WHERE T1.ItemID = @ItemID AND T1.ConditionAmt <= @ConditionAmt AND ( T2.ConditionAmt > @ConditionAmt OR T2.ConditionAmt IS NULL )


Go


Permissions

You can't post new topics.
You can't post topic replies.
You can't post new polls.
You can't post replies to polls.
You can't edit your own topics.
You can't delete your own topics.
You can't edit other topics.
You can't delete other topics.
You can't edit your own posts.
You can't edit other posts.
You can't delete your own posts.
You can't delete other posts.
You can't post events.
You can't edit your own events.
You can't edit other events.
You can't delete your own events.
You can't delete other events.
You can't send private messages.
You can't send emails.
You can read topics.
You can't vote in polls.
You can't upload attachments.
You can download attachments.
You can't post HTML code.
You can't edit HTML code.
You can't post IFCode.
You can't post JavaScript.
You can post emoticons.
You can't post or upload images.

Select a forum

































































































































































SQLServerCentral


Search