September 23, 2010 at 7:46 am
Wonder if anyone can help me.
I'm trying to write a piece of sql which will set a deleted flag to 1 where the sum of certain records on a policy = 0.
If there are 2 values say 1000.23 and -1000.23 for a specific policyid I want to set a flag in another table to delete.
For example
If a policy which has 5 entries and 2 are for 1000.23 and -1000.23 I want to identify those records which will have the same policy id do a sum on them and make sure they are 0 and then set a deleted flag in another table to deleted.
eg
Update [accountTable] set deleted = 1
where (this is the bit I can't get) sum (policyPremium) =0.
If I isolate distinct policy id values can I then search within the monetary values and look for matching +/- values in order to flag those values as deleted in the accounts table.
Any help would be greatly appreciated as I seem to be going round in circles.
Thanks
G
September 23, 2010 at 8:04 am
your issue is you need to update FROM another table...not a real table, but a summary of data in another table;
you didn't provide any details as far as the schema and columns, so this is a just a guess that is syntacticalyl correct that might get you going in the right direction:
/*
uncomment the update and comment the select if the select returns the "right" data
--UPDATE [accountTable] SET deleted = 1*/
SELECT * [accountTable]
FROM ( SELECT
POLICYID, --what is the real identifier?
SUM(policyPremium) AS policyPremium
FROM POLICYPAYMENTS --what is the real table?
GROUP BY POLICYID
HAVING SUM(policyPremium) = 0 --only the zero balance
)MySubQuery
WHERE [accountTable].POLICYID = MySubQuery.POLICYID
Lowell
September 23, 2010 at 8:10 am
Update A set deleted = (select case when sum (policyPremium) =0 then 1 else 0 end from [accountTable] I where I.PolicyID =a.PolicyID )
from [accountTable] A
September 23, 2010 at 8:11 am
another issue to consider;
avoid updating a static table based on a rollup of other information; use a view instead;
the tables could be out of sync if the process is not called after every single update to the table, something like this is better:
CREATE VIEW POLICYSTATUS
AS
SELECT CASE WHEN policyPremium = 0 THEN 'DELETED' ELSE ' OPEN' END,
MySubQuery.*
FROM (
SELECT
POLICYID, --what is the real identifier?
SUM(policyPremium) AS policyPremium
FROM POLICYPAYMENTS --what is the real table?
GROUP BY POLICYID )
MySubQuery
the above method make sure they status is always correct based on the raw data, and not based on whether an update failed or not.
Lowell
September 23, 2010 at 8:25 am
Some more detail:
Policy Key Premium
---------- ----------
123456 1002.36
123456 526.25
123456 -1002.36
456789 256.23
456789 478.25
456789 589.86
456789 -256.23
There can be multiple premium values but I'm looking for the +/- pairs out of each policy eg the 1002.36 and the 256.23 entries above.
Within each policy id I'm looking for identical values which when summed = 0 and then I want to flag those records as deleted so they don't show up on a report.
The report is pulling back every policy id and all the premium values associated with it. Unfortunately users are cancelling off values which I can't tie back by any key and they want them flagged as deleted so they don't show on the report.
Sorry if I wasn't clearer before but I'm totally stumped on how you would do that!!
September 23, 2010 at 8:36 am
DROP TABLE #Sample
CREATE TABLE #Sample ([Policy Key] int, Premium money)
INSERT INTO #Sample ([Policy Key], Premium)
SELECT 123456, 1002.36 UNION ALL
SELECT 123456, 526.25 UNION ALL
SELECT 123456, -1002.36 UNION ALL
SELECT 456789, 256.23 UNION ALL
SELECT 456789, 478.25 UNION ALL
SELECT 456789, 589.86 UNION ALL
SELECT 456789, -256.23
-- test solution
SELECT [Policy Key]
FROM #Sample
GROUP BY [Policy Key], ABS(Premium)
HAVING COUNT(*) = 2 AND SUM(Premium) = 0
ORDER BY [Policy Key]
-- output:
-- [Policy Key]
-- ------------
-- 123456
-- 456789
-- Apply solution
UPDATE s SET Flag = 1
FROM Sometable s
INNER JOIN (
SELECT [Policy Key]
FROM #Sample
GROUP BY [Policy Key], ABS(Premium)
HAVING COUNT(*) = 2 AND SUM(Premium) = 0
ORDER BY [Policy Key]
) d ON d.[Policy Key] = s.[Policy Key]
For fast, accurate and documented assistance in answering your questions, please read this article.
Understanding and using APPLY, (I) and (II) Paul White
Hidden RBAR: Triangular Joins / The "Numbers" or "Tally" Table: What it is and how it replaces a loop Jeff Moden
September 30, 2010 at 10:52 pm
your answer for 3 question is correct
hope the following helps ๐
3)
SELECT s.sid AS "Suppliers Id"
FROM suppliers s INNER JOIN catalog c
ON s.sid = c.sid INNER JOIN parts p
ON c.pid = p.pid
WHERE UPPER(p.color) = 'RED'
OR UPPER(p.color) = 'GREEN';
--------
4)
SELECT supp.suppid AS "Suppliers Id"
FROM
(SELECT COUNT(*) AS cnt
FROM parts p
WHERE UPPER(p.color) = 'RED') prod,
(SELECT COUNT(p.color) AS cnt1 , s.sid AS suppid
FROM suppliers s INNER JOIN catalog c
ON s.sid = c.sid
INNER JOIN parts p
ON c.pid = p.pid
WHERE UPPER(p.color = 'RED')) supp
WHERE supp.cnt1 = prod.cnt;
___________
Viewing 7 posts - 1 through 6 (of 6 total)
You must be logged in to reply to this topic. Login to reply