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


compare the values in the column


compare the values in the column

Author
Message
sravanb
sravanb
SSC Rookie
SSC Rookie (31 reputation)SSC Rookie (31 reputation)SSC Rookie (31 reputation)SSC Rookie (31 reputation)SSC Rookie (31 reputation)SSC Rookie (31 reputation)SSC Rookie (31 reputation)SSC Rookie (31 reputation)

Group: General Forum Members
Points: 31 Visits: 49
Hi All,

I have to compare the values in the column of the table which is a resultset of two views.
The table is something like this-

field1 field2
position1 b
position1 b
position2 a
position2 a
position3 a
position3 b

The result should be-
( the logic is-
if position(field1) has all b's the flag should be 2
if position has all a's the flag should be 1
if position has the combination of a and b the flag should be 3

field1 field2 flag
position1 b 2
position1 b 2
position2 a 1
position2 a 1
position3 a 3
position3 b 3

I dont want to create one more view on top of the actual result set which is the combination of views( performance issue.. locking etc.)
I greatly appreciate the help.
Thank you,
Sravan
andrewd.smith
andrewd.smith
SSCommitted
SSCommitted (1.6K reputation)SSCommitted (1.6K reputation)SSCommitted (1.6K reputation)SSCommitted (1.6K reputation)SSCommitted (1.6K reputation)SSCommitted (1.6K reputation)SSCommitted (1.6K reputation)SSCommitted (1.6K reputation)

Group: General Forum Members
Points: 1554 Visits: 3232
Here is your test data in a readily consumable form, i.e. a CREATE TABLE statement and an INSERT statement. Supplying test data in this form will encourage people to assist you, and therefore tends to lead to a greater number of responses in a shorter time.

CREATE TABLE #t (
field1 varchar(20) NOT NULL,
field2 char(1) NOT NULL
)

INSERT INTO #t(field1, field2)
SELECT 'position1', 'b' UNION ALL
SELECT 'position1', 'b' UNION ALL
SELECT 'position2', 'a' UNION ALL
SELECT 'position2', 'a' UNION ALL
SELECT 'position3', 'a' UNION ALL
SELECT 'position3', 'b'



I'm not sure which version of SQL Server you are using, but the following queries should work on any version of SQL Server from 2000 or later. If the field2 column cannot possibly take any value other than 'a' or 'b', the query could be written as follows:

SELECT T.field1, T.field2, CASE 
WHEN (AGG.CountA = AGG.CountAll) THEN 1
WHEN (AGG.CountB = AGG.CountAll) THEN 2
ELSE 3 END AS Flag
FROM #t AS T INNER JOIN (
SELECT field1,
COUNT(1) AS CountAll,
COUNT(CASE WHEN field2 = 'a' THEN 1 END) AS CountA,
COUNT(CASE WHEN field2 = 'b' THEN 1 END) AS CountB
FROM #t
GROUP BY field1
) AGG ON (T.field1 = AGG.field1)



This second version of the query will return NULL for the Flag column if there is any value of the field2 column in a group (grouped by field1) that is neither 'a' nor 'b'.

SELECT T.field1, T.field2, CASE 
WHEN (AGG.CountA = AGG.CountAll) THEN 1
WHEN (AGG.CountB = AGG.CountAll) THEN 2
WHEN (AGG.CountA + AGG.CountB = AGG.CountAll) THEN 3
ELSE NULL END AS Flag
FROM #t AS T INNER JOIN (
SELECT field1,
COUNT(1) AS CountAll,
COUNT(CASE WHEN field2 = 'a' THEN 1 END) AS CountA,
COUNT(CASE WHEN field2 = 'b' THEN 1 END) AS CountB
FROM #t
GROUP BY field1
) AGG ON (T.field1 = AGG.field1)


sravanb
sravanb
SSC Rookie
SSC Rookie (31 reputation)SSC Rookie (31 reputation)SSC Rookie (31 reputation)SSC Rookie (31 reputation)SSC Rookie (31 reputation)SSC Rookie (31 reputation)SSC Rookie (31 reputation)SSC Rookie (31 reputation)

Group: General Forum Members
Points: 31 Visits: 49
Thank you very much smith..
It was a great help.
sravanb
sravanb
SSC Rookie
SSC Rookie (31 reputation)SSC Rookie (31 reputation)SSC Rookie (31 reputation)SSC Rookie (31 reputation)SSC Rookie (31 reputation)SSC Rookie (31 reputation)SSC Rookie (31 reputation)SSC Rookie (31 reputation)

Group: General Forum Members
Points: 31 Visits: 49
I have one more question regarding this..

Can we store the result set in a view.
If yes how and when will the temp table is dropped.

Please help.

Thank you,
Sravan
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