October 8, 2008 at 2:12 am
Hello
I am inserting into my table into the Columns answer1 to answer10 the string "right" or "wrong".
This works fine. for example with a username
username answer1 answer2 answer3 answer4 .........
Test right wrong right right
Is there a possibility with select count to get the rate of right answers for the total : for example 5 of 10 answers right ?
October 8, 2008 at 9:15 am
first thing that comes to mind is to unpivot to turn the columns into rows then group and count. I've already had issues with getting pivot/unpivot syntax correct, so I won't post any code.
the issue here is the DB design, there shouldn't be a column for each answer, they should be on different rows. what if you had 20,30,100,1000,10000000 answers? that'd be a lot of columns.
this post should altleast get someone else out there thinking of a full answer.
October 8, 2008 at 9:17 am
This is not an optimal table design for doing what you want in SQL. It would be easier if your table was like this:
userName answerNo answer
test 1 right
test 2 wrong
test 3 right
Then you could use
select count(*) where answer = 'right'
or
select sum(case when answer = 'right' then 1 else 0 end)
As it stands you have to check each column separately with case statements, and sum the results.
select userName,
case when answer1 = 'right' then 1 else 0 end +
case when answer2 = 'right' then 1 else 0 end +
case when answer3 = 'right' then 1 else 0 end +
etc etc
__________________________________________________
Against stupidity the gods themselves contend in vain. -- Friedrich Schiller
Stop, children, what's that sound? Everybody look what's going down. -- Stephen Stills
March 1, 2010 at 7:18 am
Of course it's possible:
use tempdb
go
create table dbo.testresults (
username nvarchar(128)not null,
answer1 varchar(10) null,
answer2 varchar(10) null,
answer3 varchar(10) null,
answer4 varchar(10) null,
answer5 varchar(10) null,
answer6 varchar(10) null,
answer7 varchar(10) null,
answer8 varchar(10) null,
answer9 varchar(10) null,
answer10 varchar(10) null
);
insert dbo.TestResults(username, answer1, answer2, answer3, answer4, answer5, answer6, answer7, answer8, answer9, answer10)
select 'test', 'wrong', 'wrong', 'wrong', 'wrong', 'wrong', 'wrong', 'wrong', 'wrong', 'wrong', 'wrong'
insert dbo.TestResults(username, answer1, answer2, answer3, answer4, answer5, answer6, answer7, answer8, answer9, answer10)
select 'test2', 'wrong', 'right', 'right', 'right', 'wrong', 'wrong', 'wrong', 'wrong', 'wrong', 'right'
select
tr.username,
total.score,
total.answers
from dbo.testresults tr
cross apply (
select sum (answers.score) as score, count(*) as answers
from (
select case tr.answer1 when 'right' then 1 else 0 end as score
union all
select case tr.answer2 when 'right' then 1 else 0 end as score
union all
select case tr.answer3 when 'right' then 1 else 0 end as score
union all
select case tr.answer4 when 'right' then 1 else 0 end as score
union all
select case tr.answer5 when 'right' then 1 else 0 end as score
union all
select case tr.answer6 when 'right' then 1 else 0 end as score
union all
select case tr.answer7 when 'right' then 1 else 0 end as score
union all
select case tr.answer8 when 'right' then 1 else 0 end as score
union all
select case tr.answer9 when 'right' then 1 else 0 end as score
union all
select case tr.answer10 when 'right' then 1 else 0 end as score
) answers
) total
BUT, as the others stated already, you realy should model your tables better.
Viewing 4 posts - 1 through 3 (of 3 total)
You must be logged in to reply to this topic. Login to reply