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.
Posting Data Etiquette - Jeff ModenPosting Performance Based Questions - Gail ShawHidden RBAR - Jeff ModenCross Tabs and Pivots - Jeff ModenCatch-all queries - Gail Shaw
If you don't have time to do it right, when will you have time to do it over?