| Author |
Topic |
|
overboard22
Starting Member
13 Posts |
Posted - 2012-04-30 : 14:53:20
|
| Alright, I posted a question the other day, now I need some more help with these queries im working on. Heres the example I posted last week:so i have a table like this:fields are: PRISON ID FILE GENRE ---AK 3 A3 Female AK 4 A3 Male AK 5 A2 Female AK 6 A2 MaleAK 1 A1 MaleAK 12 A1 MaleAL 7 A4 MaleAL 8 A4 FemaleAL 9 A5 MaleAL 11 A5 MaleAL 10 A6 Malenow i need a query that will return something like this:PRISON FILE MULTIPLEIn PRISON id just need the names of the prisons. now in FILE i need a count of all the files in that prison. i already have that query. the one im having trouble with is MULTIPLE. Now in multiple i need to get how many of those FILES in each prison have both Male and Females included.in this case the results would be something like:AK 3 2 AL 3 1cos only files A3 and A2 have both Female/Male in AK and in AL only file A4 not sure if im being clear enough! but thanks so much whoever can help me out! |
|
|
visakh16
Very Important crosS Applying yaK Herder
52326 Posts |
Posted - 2012-04-30 : 15:03:52
|
| [code]SELECT PRISON,COUNT(DISTINCT FILE) AS FILE,COUNT(DISTINCT CASE WHEN CNT = 2 THEN FILE ELSE NULL END) AS MULTIPLEFROM(SELECT PRISON,FILE ,COUNT(DISTINCT GENRE) AS CNTFROM tableGROUP BY PRISON,FILE )tGROUP BY PRISON[/code]------------------------------------------------------------------------------------------------------SQL Server MVPhttp://visakhm.blogspot.com/ |
 |
|
|
overboard22
Starting Member
13 Posts |
Posted - 2012-04-30 : 15:18:32
|
| alright, thing is,PRISON is in another table, so i have to do an inner join of that table with the one that has FILE. So im wondering where this bit goes in the query?FROM dbo.Prisoner INNER JOIN dbo.Prison ON dbo.Prisoner.Prison = dbo.Prison.CLAVEJSELECT PRISON,COUNT(DISTINCT FILE) AS FILE,COUNT(DISTINCT CASE WHEN CNT = 2 THEN FILE ELSE NULL END) AS MULTIPLEFROM? after this should i put that inner join code or where? thank you so much for helping! |
 |
|
|
shilpash
Posting Yak Master
103 Posts |
Posted - 2012-04-30 : 15:32:15
|
| for the multiple,,,here you go WITH temp AS (SELECT prison ,[file] ,COUNT(genre) AS genre FROM table GROUP BY PRISON ,[file] HAVING COUNT(genre) > 1 ) SELECT prison ,COUNT(genre) AS multiple FROM temp GROUP BY prison |
 |
|
|
visakh16
Very Important crosS Applying yaK Herder
52326 Posts |
Posted - 2012-04-30 : 15:35:11
|
quote: Originally posted by overboard22 alright, thing is,PRISON is in another table, so i have to do an inner join of that table with the one that has FILE. So im wondering where this bit goes in the query?FROM dbo.Prisoner INNER JOIN dbo.Prison ON dbo.Prisoner.Prison = dbo.Prison.CLAVEJSELECT PRISON,COUNT(DISTINCT FILE) AS FILE,COUNT(DISTINCT CASE WHEN CNT = 2 THEN FILE ELSE NULL END) AS MULTIPLEFROM? after this should i put that inner join code or where? thank you so much for helping!
yep it should go after FROM SELECT PRISON,COUNT(DISTINCT FILE) AS FILE,COUNT(DISTINCT CASE WHEN CNT = 2 THEN FILE ELSE NULL END) AS MULTIPLEFROM(SELECT PRISON,FILE ,COUNT(DISTINCT GENRE) AS CNTFROM your join here GROUP BY PRISON,FILE )tGROUP BY PRISON ------------------------------------------------------------------------------------------------------SQL Server MVPhttp://visakhm.blogspot.com/ |
 |
|
|
overboard22
Starting Member
13 Posts |
Posted - 2012-04-30 : 16:03:45
|
| ok ive tried both ways and i keep getting errors about not being able to reach the PRISON table. im trying something like this:SELECT dbo.Prison.KEY, COUNT(DISTINCT File) AS File, COUNT(DISTINCT CASE WHEN CNT = 2 THEN File ELSE NULL END) AS MULTIPLEFROM (SELECT dbo.Prison.KEY, dbo.Prisoner.File, COUNT(DISTINCT dbo.Prisoner.Genre) AS CNT FROM dbo.PrisonerINNER JOIN dbo.Prison ON dbo.Prisoner.Prison = dbo.Prison.KEY GROUP BY dbo.Prison.KEY, dbo.Prisoner.File) AS tGROUP BY dbo.Prison.KEYand its telling me that it cant get the Prison.KEY data.. just wondering what im doing wrong? thanks again! |
 |
|
|
overboard22
Starting Member
13 Posts |
Posted - 2012-04-30 : 16:28:23
|
quote: Originally posted by shilpash for the multiple,,,here you go WITH temp AS (SELECT prison ,[file] ,COUNT(genre) AS genre FROM table GROUP BY PRISON ,[file] HAVING COUNT(genre) > 1 ) SELECT prison ,COUNT(genre) AS multiple FROM temp GROUP BY prison
WITH temp AS (SELECT dbo.Prison.KEY, dbo.Prisoner.File, COUNT(dbo.Prisoner.Genre) AS Genre FROM dbo.Prisoner INNER JOIN dbo.Prison ON dbo.Prisoner.Prison = dbo.Prison.KEY GROUP BY dbo.Prison.KEY, dbo.Prisoner.File HAVING (COUNT(dbo.prisoner.genre) > 1)) SELECT dbo.prison.key, COUNT(genre) AS MULTIPLE FROM temp AS temp_1 GROUP BY dbo.prison.keyand i get the same error that it cant link to prison.key |
 |
|
|
shilpash
Posting Yak Master
103 Posts |
Posted - 2012-04-30 : 18:13:36
|
| First try to do inner join in a simple way if it joins or not...SELECT * FROM dbo.PrisonerINNER JOIN dbo.PrisonON Prisoner.Prison = Prison.KeyIf it does not join,,then you are joining the wrong tables |
 |
|
|
visakh16
Very Important crosS Applying yaK Herder
52326 Posts |
Posted - 2012-05-01 : 10:03:29
|
quote: Originally posted by overboard22 ok ive tried both ways and i keep getting errors about not being able to reach the PRISON table. im trying something like this:SELECT dbo.Prison.t.KEY, COUNT(DISTINCT File) AS File, COUNT(DISTINCT CASE WHEN CNT = 2 THEN File ELSE NULL END) AS MULTIPLEFROM (SELECT dbo.Prison.KEY, dbo.Prisoner.File, COUNT(DISTINCT dbo.Prisoner.Genre) AS CNT FROM dbo.PrisonerINNER JOIN dbo.Prison ON dbo.Prisoner.Prison = dbo.Prison.KEY GROUP BY dbo.Prison.KEY, dbo.Prisoner.File) AS tGROUP BY dbo.Prison.t.KEYand its telling me that it cant get the Prison.KEY data.. just wondering what im doing wrong? thanks again!
you're using table name outside which is out of scopedo the small modification and see------------------------------------------------------------------------------------------------------SQL Server MVPhttp://visakhm.blogspot.com/ |
 |
|
|
overboard22
Starting Member
13 Posts |
Posted - 2012-05-02 : 12:19:14
|
| sorry it took me so long to reply, had the day off work! thank you so so so much! the t.KEY worked! life saver!! |
 |
|
|
visakh16
Very Important crosS Applying yaK Herder
52326 Posts |
Posted - 2012-05-02 : 19:34:29
|
| welcome------------------------------------------------------------------------------------------------------SQL Server MVPhttp://visakhm.blogspot.com/ |
 |
|
|
|