question

OnlyGraphite avatar image
OnlyGraphite asked

Count the rawdata and insert into new table

Dear All,

I need help on calculating the counts from the rawdata based on conditions and then I need to insert the values in the summary table. Currently, I have the values stored in rawdata format and I need get the counts in the summary table.

Example:

Rawdata table

Name    EmpID   Q1  Q2  Q3
John    123 3   2   1
John    123 3   2   1
John    123 2   3   4
John    123 1   3   4
Adam    125 3   5   5
Adam    125 5   4   1
Adam    125 5   2   2

Summary Table

Name    QID Question    Count of (1)    Count of (2)    Count of (3)    Count of (4)    Count of (5)
John    Q1  XXXXXXX 1       1       3       0       0
John    Q2  YYYYYYY 0       2       2       0       0
John    Q3  AAAAAA  2       0       0       2       0
Adam    Q1  XXXXXXX 0       0       1       0       2
Adam    Q2  YYYYYYY 0       1       0       1       1
Adam    Q3  AAAAAA  1       1       0       0       1

Please let me know the best approach to get this task done. I can give more information if this is not clear.

TIA!

Cheers, DV

t-sqlaggregates
10 |1200

Up to 2 attachments (including images) can be used with a maximum of 512.0 KiB each and 1.0 MiB total.

1 Answer

·
Matt Whitfield avatar image
Matt Whitfield answered

You're starting with a pivoted data set, and you want to pivot it differently - so, you want to unpivot it to a natural set, then re-pivot it to the set you want. This gives you what you want, but it doesn't match your sample, because your sample summary is wrong...

DECLARE @rawData TABLE ([Name] VARCHAR (50), q1 INT, q2 INT, q3 INT);

INSERT  INTO @rawData ([Name], [q1], [q2], [q3]) VALUES ('John', 3, 2, 1);
INSERT  INTO @rawData ([Name], [q1], [q2], [q3]) VALUES ('John', 3, 2, 1);
INSERT  INTO @rawData ([Name], [q1], [q2], [q3]) VALUES ('John', 2, 3, 4);
INSERT  INTO @rawData ([Name], [q1], [q2], [q3]) VALUES ('John', 1, 3, 4);
INSERT  INTO @rawData ([Name], [q1], [q2], [q3]) VALUES ('Adam', 3, 5, 5);
INSERT  INTO @rawData ([Name], [q1], [q2], [q3]) VALUES ('Adam', 5, 4, 1);
INSERT  INTO @rawData ([Name], [q1], [q2], [q3]) VALUES ('Adam', 5, 2, 2);

  SELECT [Name], [QID], [1], [2], [3], [4], [5]
    FROM ( SELECT [Name], [Marks], [QID]
             FROM @rawData 
          UNPIVOT (Marks FOR [QID] IN (q1, q2, q3)) AS upv) AS idat
   PIVOT (COUNT (Marks) FOR Marks IN ([1], [2], [3], [4], [5])) AS pvt
ORDER BY [Name], [QID];
10 |1200

Up to 2 attachments (including images) can be used with a maximum of 512.0 KiB each and 1.0 MiB total.

Write an Answer

Hint: Notify or tag a user in this post by typing @username.

Up to 2 attachments (including images) can be used with a maximum of 512.0 KiB each and 1.0 MiB total.