October 1, 2012 at 9:36 am
Hello,
I've been trying to figure out how to solve this for a while, with no success.
I have 2 tables:
1)
QUESTIONS
ID (pk)
QUES
ORD
2)
ANSWERS
ID (pk)
QUES_ID (fk)
SURV_ID (fk)
ANSW
Now I need to create a view, where the questions are the columns names and for each SURV_ID there is a row in the view with answer NULL if there is no entry in ANSWERS or answer ANSW if there is an entry.
Not sure if it is possible to do it with JOINs.
I was thinking to use a CURSOR, then do the UNION of the resulting tables, then use a PIVOT, but not sure it's the best solutions + I don't know how to do the union through the loops...
DECLARE @survid int
DECLARE db_cursor CURSOR FOR
SELECT DISTINCT SURV_ID FROM ANSWERS ORDER BY SURV_ID
OPEN db_cursor
FETCH NEXT FROM db_cursor INTO @survid
WHILE @@FETCH_STATUS = 0
BEGIN
SELECT QUES
,ANSW , SURV_ID
FROM QUESTIONS a
left outer JOIN ANSWERS b ON a.ID = b.QUES_ID
WHERE ( SURV_ID = @survid OR SURV_ID IS NULL)
FETCH NEXT FROM db_cursor INTO @survid
END
CLOSE db_cursor
DEALLOCATE db_cursor
....
Thanks for your time and your help!
October 1, 2012 at 9:58 am
there's no need for a cursor on this, but I think youa re right, you will need to pivot the rows to columns;
is there a fixed number of answers for each question, or does it vary?
is there a maximum number of answers for each question, ie 4 for a multipel choice question?
here's an example i adapted, since i didn't want to guess at your DDL for your tables.
note that if you can provide the data in the same format int he future, you can get exact, tested answers to your problems:
CREATE TABLE Question (QuestionID INT , QuestionName VARCHAR(255))
INSERT INTO Question values (1,'First Question')
INSERT INTO Question values (2,'Second Question')
go
CREATE TABLE Question_items (QuestionID INT , ItemID INT )
INSERT INTO Question_items values (1, 10)
INSERT INTO Question_items values (1, 20)
INSERT INTO Question_items values (1, 30)
INSERT INTO Question_items values (1, 40)
INSERT INTO Question_items values (2, 50)
INSERT INTO Question_items values (2, 60)
INSERT INTO Question_items values (2, 70)
INSERT INTO Question_items values (2, 80)
go
;with cte as
(
select QuestionID ,ItemID,
row_number() over (partition by QuestionID order by ItemID desc) RN
from Question_items
)
--select * from
select QuestionID,[1] as Val1,[2] as Val2,[3] as Val3,[4] as Val4 from
( select * from cte where RN <= 4 ) pivot_handle
pivot
(MAX(ItemID) for RN in ([1],[2],[3],[4])) pivot_table
Lowell
October 1, 2012 at 1:16 pm
For some reasons, everyone a while I COULD NOT post the code using any of IFcode. there is some issue with @ or #. Anyone see similar issue witht this forum?
I was about to post my solution. but I couldn't...frustrated.
October 1, 2012 at 3:39 pm
haiao2000 (10/1/2012)
For some reasons, everyone a while I COULD NOT post the code using any of IFcode. there is some issue with @ or #. Anyone see similar issue witht this forum?I was about to post my solution. but I couldn't...frustrated.
Put the code in [ code="sql" ]...[ /code ] (had to put spaces before and after the [ and ] so the code would be processed...)
@ # no problem...
October 1, 2012 at 3:44 pm
PiMané (10/1/2012)
haiao2000 (10/1/2012)
For some reasons, everyone a while I COULD NOT post the code using any of IFcode. there is some issue with @ or #. Anyone see similar issue witht this forum?I was about to post my solution. but I couldn't...frustrated.
Put the code in
...\[/code]
you bet!!!, that is the first thing I tried. it didnt work. some days it just doesn't work. everytime I hit submit it just blows up like overloaded balloon.
it said: Internet Explorer could find the webpage....shame!
October 1, 2012 at 3:54 pm
haiao2000 (10/1/2012)you bet!!!, that is the first thing I tried. it didnt work. some days it just doesn't work. everytime I hit submit it just blows up like overloaded balloon.
it said: Internet Explorer could find the webpage....shame!
I use FireFox 🙂
No problem with that...
October 2, 2012 at 2:35 am
Hi Lowell,
thank you for you help so far. The problem that I am facing is a bit more complicated, since not the questions have an answer (in that case I'm happy to show NULL), and answers are grouped by a SURV_ID
CREATE TABLE [QUESTIONS] (
[ID] [int] IDENTITY(1,1) NOT NULL,
[QUES] [varchar](250) NOT NULL,
[ORD] [int] NOT NULL,
CONSTRAINT [PK_QUESTIONS] PRIMARY KEY CLUSTERED
(
[ID] ASC
)WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, IGNORE_DUP_KEY = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON) ON [PRIMARY]
) ON [PRIMARY]
GO
INSERT INTO [QUESTIONS] values ('First Question', 1)
INSERT INTO [QUESTIONS] values ('Second Question', 2)
GO
CREATE TABLE [ANSWERS] (
[ID] [int] IDENTITY(1,1) NOT NULL,
[SURV_ID] [int] NOT NULL,
[QUES_ID] [int] NOT NULL,
[ANSW] [varchar](500) NOT NULL,
CONSTRAINT [PK_ANSWERS] PRIMARY KEY CLUSTERED
(
[ID] ASC
)WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, IGNORE_DUP_KEY = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON) ON [PRIMARY]
) ON [PRIMARY]
GO
SET ANSI_PADDING OFF
GO
ALTER TABLE [ANSWERS] WITH CHECK ADD CONSTRAINT [FK_ANSWERS_QUESTIONS] FOREIGN KEY([QUES_ID])
REFERENCES [QUESTIONS] ([ID])
GO
ALTER TABLE [ANSWERS] CHECK CONSTRAINT [FK_ANSWERS_QUESTIONS]
GO
INSERT INTO [ANSWERS] ([SURV_ID],[QUES_ID],[ANSW]) VALUES (1,1,'Y')
INSERT INTO [ANSWERS] ([SURV_ID],[QUES_ID],[ANSW]) VALUES (1,2,'N')
INSERT INTO [ANSWERS] ([SURV_ID],[QUES_ID],[ANSW]) VALUES (2,1,'N')
INSERT INTO [ANSWERS] ([SURV_ID],[QUES_ID],[ANSW]) VALUES (3,2,'Y')
INSERT INTO [ANSWERS] ([SURV_ID],[QUES_ID],[ANSW]) VALUES (4,1,'Y')
INSERT INTO [ANSWERS] ([SURV_ID],[QUES_ID],[ANSW]) VALUES (4,2,'Y')
GO
What I would like to get, is something like the image in attachment
October 2, 2012 at 3:21 am
Hi,
this does the job
SELECT DISTINCT a.Surv_id, (SELECT ANSW FROM ANSWERS t WHERE t.QUES_ID = 1 AND t.SURV_ID = a.SURV_ID) [First Question], (SELECT ANSW FROM ANSWERS t WHERE t.QUES_ID = 2 AND t.SURV_ID = a.SURV_ID) [Second Question] FROM ANSWERS a
But the questions are "hard coded"... t.ID = 1 ..
With PIVOT the result is the same but, like all PIVOT, the columns (referring the questions) are also "hard coded"
SELECT SURV_ID, [First Question], [Second Question]
FROM
(SELECT s.SURV_ID, q.QUES, a.ANSW FROM
(
(SELECT DISTINCT SURV_ID FROM ANSWERS) s
CROSS JOIN Questions q
LEFT JOIN ANSWERS a ON a.SURV_ID = s.SURV_ID AND q.ID = a.QUES_ID
)
)
AS SrcData
PIVOT (
MAX(ANSW)
FOR QUES IN ([First Question], [Second Question])
) AS pivotData
You can build a dynamic SQL and execute it to build the query according to the existing questions.
Pedro
October 2, 2012 at 4:00 am
gianlud75 (10/2/2012)
...What I would like to get, is something like the image in attachment
You have to use dynamic sql for this. The core query is this:
SELECT
a.SURV_ID,
[First Question] = MAX(CASE WHEN q.QUES = 'First Question' THEN a.ANSW ELSE NULL END),
[Second Question] = MAX(CASE WHEN q.QUES = 'Second Question' THEN a.ANSW ELSE NULL END)
FROM [QUESTIONS] q
LEFT JOIN [ANSWERS] a
ON a.QUES_ID = q.ID
GROUP BY a.SURV_ID
However, the questions cannot be hard-coded, they have to come from the data. So, we build up the statement using the data from the questions table:
DECLARE @Statement VARCHAR(1000)
SET @Statement = 'SELECT a.SURV_ID'
SELECT
@Statement = @Statement + ','+CHAR(10)+' [' + q.QUES + '] = MAX(CASE WHEN q.QUES = ''' + q.QUES + ''' THEN a.ANSW ELSE NULL END)'
FROM [QUESTIONS] q
ORDER BY q.ID
SET @Statement = @Statement + '
FROM [QUESTIONS] q
LEFT JOIN [ANSWERS] a
ON a.QUES_ID = q.ID
GROUP BY a.SURV_ID'
PRINT @Statement
EXEC (@Statement)
Heres the result of the PRINT
SELECT a.SURV_ID,
[First Question] = MAX(CASE WHEN q.QUES = 'First Question' THEN a.ANSW ELSE NULL END),
[Second Question] = MAX(CASE WHEN q.QUES = 'Second Question' THEN a.ANSW ELSE NULL END)
FROM [QUESTIONS] q
LEFT JOIN [ANSWERS] a
ON a.QUES_ID = q.ID
GROUP BY a.SURV_ID
😉
EDIT: added result of PRINT
For fast, accurate and documented assistance in answering your questions, please read this article.
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
October 2, 2012 at 7:25 am
Need to modify it slightly to fit your requirements. but this is my solution to rotate table vertically
Look like forum does not allow the drop statements for temporary tables, that was why it blew up (both on IE and firefox), so add 3 drop statements for temp tables at the end.
--create some test tables with test data for demo purpose
create table #question (questionId int identity(1,1), question varchar(100) )
create table #answer (answerId int identity(1,1), questionId int, answer varchar(100))
insert into #question(question)
select 'You are old?' union all
select 'You are smart?' union all
select 'You are rich?' union all
select 'You are loved?'
insert into #answer(questionId, answer)
select 1,'True' union all
select 2,'False' union all
select 3,'False'
--retrieve desired data
create table #temp (fieldName varchar(100),fieldValue varchar(100), sortOrder int identity(1,1) )
insert into #temp(fieldName,fieldValue)
exec ('select question, answer from #answer right join #question on #answer.questionid=#question.questionId where 1=1');
--generate sql statement to rotate table dynamically
declare @sql as varchar(8000)
set @sql = 'select ';
select @sql = @sql + '[' + fieldName+']=isnull((select fieldValue from #temp where fieldName='''+fieldName+'''),null),'
from #temp
order by sortOrder
set @sql = SUBSTRING(@sql, 1, LEN(@sql)-1)
print @sql
exec(@sql)
October 2, 2012 at 9:01 am
Thank you everybody!
ChrisM@Work's solution works for me.
I only needed to increase the varchar size to 8000 to accommodate more Questions.
Not sure if there is a neater solution, but this one works well for now.
Thanks ChrisM@Work and thank you all!
Viewing 11 posts - 1 through 10 (of 10 total)
You must be logged in to reply to this topic. Login to reply