Click here to monitor SSC
SQLServerCentral is supported by Red Gate Software Ltd.
 
Log in  ::  Register  ::  Not logged in
 
 
 
        
Home       Members    Calendar    Who's On


Add to briefcase

Unpivot question, struggling with data please help Expand / Collapse
Author
Message
Posted Sunday, September 2, 2012 12:49 PM
Forum Newbie

Forum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum Newbie

Group: General Forum Members
Last Login: Monday, September 3, 2012 12:25 PM
Points: 4, Visits: 40
Have a table with the following structure ..

recordid (int), column1a (int), column2a (bit), columns3a (bit), column4a (bit), column1b (int), column2b (bit), column3b (bit), column4b (bit)

up to 100. (it's one of those forms converted to a table... i know terrible format)

Anyway, I need to change it to.

recordid, column1, column2, column3, column4
a
b
c
d
e
... etc.

The unpivot seems like the best solution, but I can't figure out how to group more than 1 column. Any help would be very much appreciated.
Post #1353268
Posted Sunday, September 2, 2012 4:07 PM


SSCommitted

SSCommittedSSCommittedSSCommittedSSCommittedSSCommittedSSCommittedSSCommittedSSCommitted

Group: General Forum Members
Last Login: Today @ 2:44 PM
Points: 1,945, Visits: 2,862
>> I have a table with the following structure <<

Please post DDL, so that people do not have to guess what the keys, constraints, Declarative Referential Integrity, data types, etc. in your schema are. The use of BIT is a nightmare of non-RDBMS mindsets and we need to know if it is NULL-able or not. I also loved the use of “record_id” for a data element. Still stuck in punch cards and mag tapes.

Here is my guess:

CREATE TABLE Garbage
(record_id INTEGER NOT NULL PRIMARY KEY,
column1a INTEGER NOT NULL,
column2a BIT DEFAULT CAST (0 AS BIT) NOT NULL,
column3a BIT DEFAULT CAST (0 AS BIT) NOT NULL,
column4a BIT DEFAULT CAST (0 AS BIT) NOT NULL,
column1b INTEGER NOT NULL,
column2b BIT DEFAULT CAST (0 AS BIT) NOT NULL,
column3b BIT DEFAULT CAST (0 AS BIT) NOT NULL,
column4b BIT DEFAULT CAST (0 AS BIT) NOT NULL);

>> it's one of those forms converted to a table... I know terrible format. Anyway, I need to change it to:

record_id, column1, column2, column3, column4
a
b
c
d
e
... etc. <<

No, you need to fire the moron that wrote this and re-do all his code. Then you need to put it into a normalized table with usable data element names. This is just a spreadsheet and not something you could use in s correct RDBMS.

Again, without specs, I would guess that each block of
{column1x INTEGER NOT NULL,
column2x BIT DEFAULT CAST (0 AS BIT) NOT NULL,
column3x BIT DEFAULT CAST (0 AS BIT) NOT NULL,
column4x BIT DEFAULT CAST (0 AS BIT) NOT NULL}

is an attribute splitting problem that is more like a hand grenade than we usually see in a bad design. I think these are really a single attribute of whatever this thing is supposed to model.

Can you explain what this means?


Books in Celko Series for Morgan-Kaufmann Publishing
Analytics and OLAP in SQL
Data and Databases: Concepts in Practice
Data, Measurements and Standards in SQL
SQL for Smarties
SQL Programming Style
SQL Puzzles and Answers
Thinking in Sets
Trees and Hierarchies in SQL
Post #1353285
Posted Sunday, September 2, 2012 4:37 PM
Forum Newbie

Forum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum Newbie

Group: General Forum Members
Last Login: Monday, September 3, 2012 12:25 PM
Points: 4, Visits: 40
Celko- thanks for the response.

Archaic is right on the money.

Your guess is right on about the structure. I was wrong it's actually nvarchar(30) instead of bit. Holding "True" and "False" data and the int columns are an ID. (but no foreign key constraint... of course)

[record_id] [int] IDENTITY(1,1) NOT NULL,
[Column1a] [int] NULL,
[Column2a] [nvarchar](30) NULL,
[Column3a] [nvarchar](30) NULL,
[Column4a] [nvarchar](30) NULL,
[Column1b] [int] NULL,
[Column2b] [nvarchar](30) NULL,
[Column3b] [nvarchar](30) NULL,
[Column4b] [nvarchar](30) NULL,
Post #1353287
Posted Sunday, September 2, 2012 5:26 PM


SSCommitted

SSCommittedSSCommittedSSCommittedSSCommittedSSCommittedSSCommittedSSCommittedSSCommitted

Group: General Forum Members
Last Login: Today @ 2:44 PM
Points: 1,945, Visits: 2,862
Yuck! But what does it mean? What is it supposed to model? This needs to be thrown out so you start over.

Books in Celko Series for Morgan-Kaufmann Publishing
Analytics and OLAP in SQL
Data and Databases: Concepts in Practice
Data, Measurements and Standards in SQL
SQL for Smarties
SQL Programming Style
SQL Puzzles and Answers
Thinking in Sets
Trees and Hierarchies in SQL
Post #1353290
Posted Sunday, September 2, 2012 5:40 PM
Forum Newbie

Forum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum Newbie

Group: General Forum Members
Last Login: Monday, September 3, 2012 12:25 PM
Points: 4, Visits: 40
Not an option at this point. Again it's from a form. The form was designed like a grid.

Any thoughts?
Post #1353291
Posted Sunday, September 2, 2012 6:54 PM


Hall of Fame

Hall of FameHall of FameHall of FameHall of FameHall of FameHall of FameHall of FameHall of FameHall of Fame

Group: General Forum Members
Last Login: Today @ 10:07 PM
Points: 3,617, Visits: 5,236
You're a bit scant on sample data, but we'll take a stab at it anyway. You can see in this example how to UNPIVOT single or multiple columns, so you should be able to manipulate it to get it where you need it to be.

DECLARE @t TABLE (
[record_id] [int] IDENTITY(1,1) NOT NULL,
[Column1a] [int] NULL,
[Column2a] [nvarchar](30) NULL,
[Column3a] [nvarchar](30) NULL,
[Column4a] [nvarchar](30) NULL,
[Column1b] [int] NULL,
[Column2b] [nvarchar](30) NULL,
[Column3b] [nvarchar](30) NULL,
[Column4b] [nvarchar](30) NULL)

INSERT INTO @t
SELECT 1, 'A', 'B', 'C', 2, 'D', 'E', 'F'

SELECT record_id, num, alpha1, alpha2
FROM @t
CROSS APPLY (
VALUES (Column1a), (Column1b)) nums(num)
CROSS APPLY (
VALUES (Column2a, Column2b), (Column3a, Column3b), (Column4a, Column4b)) alphas(alpha1, alpha2)


You can read about the CROSS APPLY VALUES approach to UNPIVOT here:
http://www.sqlservercentral.com/articles/CROSS+APPLY+VALUES+UNPIVOT/91234/

The discussion thread has some good information on performance compared to UNPIVOT.



My mantra: No loops! No CURSORs! No RBAR! Hoo-uh!

My thought question: Have you ever been told that your query runs too fast?

My advice:
INDEXing a poor-performing query is like putting sugar on cat food. Yeah, it probably tastes better but are you sure you want to eat it?
The path of least resistance can be a slippery slope. Take care that fixing your fixes of fixes doesn't snowball and end up costing you more than fixing the root cause would have in the first place.


Need to UNPIVOT? Why not CROSS APPLY VALUES instead?
Since random numbers are too important to be left to chance, let's generate some!
Learn to understand recursive CTEs by example.
Splitting strings based on patterns can be fast!
Post #1353295
Posted Sunday, September 2, 2012 7:15 PM
Forum Newbie

Forum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum Newbie

Group: General Forum Members
Last Login: Monday, September 3, 2012 12:25 PM
Points: 4, Visits: 40
Sorry dwain .. data

INSERT INTO [Table]
SELECT 1234, 1, 'True', 'False', 'False', 2, 'False', 'False', 'False', 3, 'True', 'True', 'True', 4, 'False', 'False', 'False'


One other complication, looking to filter and only show column1,2,3,4 When 2 or 3, or 4 = 'True'

Result should be something like

recordid column1, column2, column3, column4
1234 1 true f f
1234 3 true true true


Looking at your cross apply now. Thanks for the link hadn't seen that.
Post #1353299
Posted Sunday, September 2, 2012 7:28 PM


Hall of Fame

Hall of FameHall of FameHall of FameHall of FameHall of FameHall of FameHall of FameHall of FameHall of Fame

Group: General Forum Members
Last Login: Today @ 10:07 PM
Points: 3,617, Visits: 5,236
Dwight617 (9/2/2012)
Sorry dwain .. data

INSERT INTO [Table]
SELECT 1234, 1, 'True', 'False', 'False', 2, 'False', 'False', 'False', 3, 'True', 'True', 'True', 4, 'False', 'False', 'False'


One other complication, looking to filter and only show column1,2,3,4 When 2 or 3, or 4 = 'True'

Result should be something like

recordid column1, column2, column3, column4
1234 1 true f f
1234 3 true true true


Looking at your cross apply now. Thanks for the link hadn't seen that.


Ah! Clarity!

DECLARE @t TABLE (
[record_id] [int] NOT NULL,
[Column1a] [int] NULL,
[Column2a] [nvarchar](30) NULL,
[Column3a] [nvarchar](30) NULL,
[Column4a] [nvarchar](30) NULL,
[Column1b] [int] NULL,
[Column2b] [nvarchar](30) NULL,
[Column3b] [nvarchar](30) NULL,
[Column4b] [nvarchar](30) NULL,
[Column1c] [int] NULL,
[Column2c] [nvarchar](30) NULL,
[Column3c] [nvarchar](30) NULL,
[Column4c] [nvarchar](30) NULL,
[Column1d] [int] NULL,
[Column2d] [nvarchar](30) NULL,
[Column3d] [nvarchar](30) NULL,
[Column4d] [nvarchar](30) NULL
)

INSERT INTO @t
SELECT 1234, 1, 'True', 'False', 'False', 2, 'False', 'False', 'False', 3, 'True', 'True', 'True', 4, 'False', 'False', 'False'

SELECT record_id, col1, col2, col3, col4
FROM @t
CROSS APPLY (
VALUES (Column1a, Column2a, Column3a, Column4a)
,(Column1b, Column2b, Column3b, Column4b)
,(Column1c, Column2c, Column3c, Column4c)
,(Column1d, Column2d, Column3d, Column4d)) alphas(col1, col2, col3, col4)
WHERE col2 = 'True' OR col3 = 'True' OR col4 = 'True'


Edit: Minor but important correction to the query.



My mantra: No loops! No CURSORs! No RBAR! Hoo-uh!

My thought question: Have you ever been told that your query runs too fast?

My advice:
INDEXing a poor-performing query is like putting sugar on cat food. Yeah, it probably tastes better but are you sure you want to eat it?
The path of least resistance can be a slippery slope. Take care that fixing your fixes of fixes doesn't snowball and end up costing you more than fixing the root cause would have in the first place.


Need to UNPIVOT? Why not CROSS APPLY VALUES instead?
Since random numbers are too important to be left to chance, let's generate some!
Learn to understand recursive CTEs by example.
Splitting strings based on patterns can be fast!
Post #1353301
Posted Sunday, September 2, 2012 9:04 PM


Hall of Fame

Hall of FameHall of FameHall of FameHall of FameHall of FameHall of FameHall of FameHall of FameHall of Fame

Group: General Forum Members
Last Login: Today @ 10:07 PM
Points: 3,617, Visits: 5,236
Let me explain a little further about the CROSS APPLY.

CROSS APPLY (
VALUES (Column1a, Column2a, Column3a, Column4a)
,(Column1b, Column2b, Column3b, Column4b)
,(Column1c, Column2c, Column3c, Column4c)
,(Column1d, Column2d, Column3d, Column4d)) alphas(col1, col2, col3, col4)


Looking down through the columns constructed by VALUES, for col1 it consists of Column1a, Column1b, Column1c and Column1d. So all of these must be of the same data type (or CAST to the same data type).

To add more columns, e.g., e, f and g, you'd want something like:

CROSS APPLY (
VALUES (Column1a, Column2a, Column3a, Column4a)
,(Column1b, Column2b, Column3b, Column4b)
,(Column1c, Column2c, Column3c, Column4c)
,(Column1d, Column2d, Column3d, Column4d)
,(Column1e, Column2e, Column3e, Column4e)
,(Column1f, Column2f, Column3f, Column4f)
,(Column1g, Column2g, Column3g, Column4g)
) alphas(col1, col2, col3, col4)


The number of columns produced in table "alphas" corresponds to the number of columns appearing in each () grouping of the VALUES set (Table Row Constructor).



My mantra: No loops! No CURSORs! No RBAR! Hoo-uh!

My thought question: Have you ever been told that your query runs too fast?

My advice:
INDEXing a poor-performing query is like putting sugar on cat food. Yeah, it probably tastes better but are you sure you want to eat it?
The path of least resistance can be a slippery slope. Take care that fixing your fixes of fixes doesn't snowball and end up costing you more than fixing the root cause would have in the first place.


Need to UNPIVOT? Why not CROSS APPLY VALUES instead?
Since random numbers are too important to be left to chance, let's generate some!
Learn to understand recursive CTEs by example.
Splitting strings based on patterns can be fast!
Post #1353314
« Prev Topic | Next Topic »

Add to briefcase

Permissions Expand / Collapse