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


please help with query


please help with query

Author
Message
ericb1
ericb1
SSC Veteran
SSC Veteran (220 reputation)SSC Veteran (220 reputation)SSC Veteran (220 reputation)SSC Veteran (220 reputation)SSC Veteran (220 reputation)SSC Veteran (220 reputation)SSC Veteran (220 reputation)SSC Veteran (220 reputation)

Group: General Forum Members
Points: 220 Visits: 337
This should be straightforward, I just don't know how to write it, any help is appreciated.

I have 2 tables, one lists information about different account types:

ID notes account1 account2 account3 account4 account5
1 notes 1 0 1 0 1
2 notes 0 1 0 1 0
3 notes 1 0 1 0 0

the account types are type "bit" to indicate yes or no that the notes in the row apply to that account type.

The 2nd table is a user table and there is a field called "lastaccounttype" where it lists the last account type a user has been assigned to. SO it would have:

user lastaccounttype
ericb1 account1


I am trying to wite a query that selects only the rows from the notes table where the bit flag for the note is the same account type as the "lastaccounttype". So in the example above, it would only return rows 1 and 3 where the bit flag for "account1" was set to yes (or 1).

Not sure if I need 5 case statements, or if there is another way to write this? Any help is greatly appreciated, thanks!
Thinknook
Thinknook
SSC Veteran
SSC Veteran (209 reputation)SSC Veteran (209 reputation)SSC Veteran (209 reputation)SSC Veteran (209 reputation)SSC Veteran (209 reputation)SSC Veteran (209 reputation)SSC Veteran (209 reputation)SSC Veteran (209 reputation)

Group: General Forum Members
Points: 209 Visits: 164990
I think an easy options is to Pivot using the UNPIVOT statement

This will transpose your Account1, Account2 columns into one column called "AccountType", then you can do a join on AccountType using the LastAccountType of your 2nd table.

So for your query it would look something like this:



;WITH cte as -- Used a CTE to generate the sample values in your 1st table
( SELECT *
FROM
(VALUES(1, 'notes', 1, 0, 1, 0, 1),(2, 'notes', 1, 0, 1, 0, 1),(3, 'notes', 1, 0, 1, 0, 1)) as t(id,note,ac1,ac2,ac3,ac4,ac5) --SAMPLE VALUES
)
SELECT id, note, AccountTypeID,IncludeNote
FROM
(SELECT id, note, ac1, ac2, ac3, ac4, ac5
FROM cte) p
UNPIVOT
(IncludeNote FOR AccountTypeID IN
(ac1, ac2, ac3, ac4, ac5))AS unpvt;




Then you can just join on AccountTypeID using the 2nd table, and filter by IncludeNote

Hope this helps!

-----------------
... Then again, I could be totally wrong! Check the answer.
Check out posting guidelines here for faster more precise answers.

I believe in Codd
... and Thinknook is my Chamber of Understanding
ChrisM@home
ChrisM@home
SSCrazy
SSCrazy (2.1K reputation)SSCrazy (2.1K reputation)SSCrazy (2.1K reputation)SSCrazy (2.1K reputation)SSCrazy (2.1K reputation)SSCrazy (2.1K reputation)SSCrazy (2.1K reputation)SSCrazy (2.1K reputation)

Group: General Forum Members
Points: 2071 Visits: 10376
-- sample data
;WITH
MySample (ID, notes, account1, account2, account3, account4, account5) AS (
SELECT 1, 'notes', 1, 0, 1, 0, 1 UNION ALL
SELECT 2, 'notes', 0, 1, 0, 1, 0 UNION ALL
SELECT 3, 'notes', 1, 0, 1, 0, 0),

UserTable ([user], lastaccounttype) AS (SELECT 'ericb1', 'account1' UNION ALL SELECT 'Yotam Ottolenghi','account5')

-- solution
SELECT s.ID, s.notes, x.*, u.[user]
FROM MySample s
CROSS APPLY (
VALUES
(s.account1,'Account1'),
(s.account2,'Account2'),
(s.account3,'Account3'),
(s.account4,'Account4'),
(s.account5,'Account5')
) x (Flag, [Account])
INNER JOIN UserTable u
ON u.lastaccounttype = x.Account
AND x.Flag = 1
ORDER BY u.[user]




Low-hanging fruit picker and defender of the moggies





For better assistance in answering your questions, please read this.




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
ScottPletcher
ScottPletcher
SSCertifiable
SSCertifiable (8K reputation)SSCertifiable (8K reputation)SSCertifiable (8K reputation)SSCertifiable (8K reputation)SSCertifiable (8K reputation)SSCertifiable (8K reputation)SSCertifiable (8K reputation)SSCertifiable (8K reputation)

Group: General Forum Members
Points: 7997 Visits: 7160
Here's an alternative:


SELECT u.*, n.ID, n.notes
FROM UserTable u
INNER JOIN Notes n ON
(u.lastaccounttype = 'account1' AND n.account1 = 1) OR
(u.lastaccounttype = 'account2' AND n.account2 = 1) OR
(u.lastaccounttype = 'account3' AND n.account3 = 1) OR
(u.lastaccounttype = 'account4' AND n.account4 = 1) OR
(u.lastaccounttype = 'account5' AND n.account5 = 1)



Edit: Added the sql and /code tags around the SQL.

SQL DBA,SQL Server MVP(07, 08, 09)[size=2]Prosecutor James Blackburn, in closing argument in the Fatal Vision murders trial: If in the future, you should cry a tear, cry one for them [the murder victims]. If in the future, you should say a prayer, say one for them. And if in the future, you should light a candle, light one for them.[/size]
ericb1
ericb1
SSC Veteran
SSC Veteran (220 reputation)SSC Veteran (220 reputation)SSC Veteran (220 reputation)SSC Veteran (220 reputation)SSC Veteran (220 reputation)SSC Veteran (220 reputation)SSC Veteran (220 reputation)SSC Veteran (220 reputation)

Group: General Forum Members
Points: 220 Visits: 337
excellent! Thanks for the sample!
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