January 1, 2013 at 8:24 pm
Hi all,
not sure how best to explain what I'm trying to do so will try to break it down as easy as i can.
I have a table which stores all prices for companies daily trading. Companies ABC & XYZ have information available for what was the high & low values for a DateID.
CREATE TABLE [dbo].[TestGrid]
(
[ID] [int] IDENTITY(1,1) NOT NULL,
[CompanyName] [varchar](200) NOT NULL,
[DateID] [int] NOT NULL,
[High] [float] NOT NULL,
[Low] [float] NOT NULL
)
INSERT INTO [dbo].[TestGrid] (CompanyName,DateID,High,Low)
VALUES ('ABC',20121201,0.5,1.0)
INSERT INTO [dbo].[TestGrid] (CompanyName,DateID,High,Low)
VALUES ('ABC',20121202,0.6,1.5)
INSERT INTO [dbo].[TestGrid] (CompanyName,DateID,High,Low)
VALUES ('ABC',20121203,1.0,1.6)
INSERT INTO [dbo].[TestGrid] (CompanyName,DateID,High,Low)
VALUES ('XYZ',20121201,0.5,0.4)
INSERT INTO [dbo].[TestGrid] (CompanyName,DateID,High,Low)
VALUES ('XYZ',20121202,0.6,0.5)
INSERT INTO [dbo].[TestGrid] (CompanyName,DateID,High,Low)
VALUES ('XYZ',20121203,1.0,0.6)
ID CompanyName DateID High Low
----------- ----------------------------------------------------------
1 ABC 20121201 0.5 0.1
2 ABC 20121202 0.6 0.5
3 ABC 20121203 1 0.6
4 XYZ 20121201 0.5 0.4
5 XYZ 20121202 0.6 0.5
6 XYZ 20121203 1 0.6
What I'm trying to do is turn the DateID into columns and then as a additional change those columns represent the actual day of the Date ID How would i know 20121201 is equal to say Monday and 02 is Tuesday?
END RESULT:
NAME TYPE MONDAY TUESDAY WEDNESDAY
ABC HIGH 0.5 0.6 1
ABC LOW 0.1 1.5 0.6
I'm not sure if cross join / pivot or something else should be used so if i could get a hand would be great
January 1, 2013 at 9:03 pm
You might try this:
SELECT CompanyName, Type
,Sunday=MAX(CASE WHEN weekday = 1 THEN Val END)
,Monday=MAX(CASE WHEN weekday = 2 THEN Val END)
,Tuesday=MAX(CASE WHEN weekday = 3 THEN Val END)
,Wednesday=MAX(CASE WHEN weekday = 4 THEN Val END)
,Thursday=MAX(CASE WHEN weekday = 5 THEN Val END)
,Friday=MAX(CASE WHEN weekday = 6 THEN Val END)
,Saturday=MAX(CASE WHEN weekday = 7 THEN Val END)
FROM dbo.TestGrid
CROSS APPLY (
VALUES(High, 'High', DATEPART(dw, CAST(DateID AS CHAR(8))))
,(Low, 'Low', DATEPART(dw, CAST(DateID AS CHAR(8))))) a(Val, Type, weekday)
GROUP BY CompanyName, Type
And you will also want to Google "SQL DATEFIRST" to see how this query is sensitive to that setting.
You can look at the first link in my signature to see how the CROSS APPLY VALUES works (like an UNPIVOT but usually faster).
I won't ask (but should) why (before someone else does) you're storing a date as an INT instead of a DATETIME.
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?[/url]
Since random numbers are too important to be left to chance, let's generate some![/url]
Learn to understand recursive CTEs by example.[/url]
[url url=http://www.sqlservercentral.com/articles/St
January 2, 2013 at 7:40 am
dwain.c (1/1/2013)
You might try this:
SELECT CompanyName, Type
,Sunday=MAX(CASE WHEN weekday = 1 THEN Val END)
,Monday=MAX(CASE WHEN weekday = 2 THEN Val END)
,Tuesday=MAX(CASE WHEN weekday = 3 THEN Val END)
,Wednesday=MAX(CASE WHEN weekday = 4 THEN Val END)
,Thursday=MAX(CASE WHEN weekday = 5 THEN Val END)
,Friday=MAX(CASE WHEN weekday = 6 THEN Val END)
,Saturday=MAX(CASE WHEN weekday = 7 THEN Val END)
FROM dbo.TestGrid
CROSS APPLY (
VALUES(High, 'High', DATEPART(dw, CAST(DateID AS CHAR(8))))
,(Low, 'Low', DATEPART(dw, CAST(DateID AS CHAR(8))))) a(Val, Type, weekday)
GROUP BY CompanyName, Type
And you will also want to Google "SQL DATEFIRST" to see how this query is sensitive to that setting.
You can look at the first link in my signature to see how the CROSS APPLY VALUES works (like an UNPIVOT but usually faster).
I won't ask (but should) why (before someone else does) you're storing a date as an INT instead of a DATETIME.
Try this, it shouldn't be sensitive to the DATEFIRST setting. It relies on 1900-01-01 being a Monday.
SELECT
CompanyName
,Type
,Sunday = MAX(CASE WHEN weekday = datename(dw, dateadd(dd, 1 - 2, '19000101')) THEN Val END)
,Monday = MAX(CASE WHEN weekday = datename(dw, dateadd(dd, 2 - 2, '19000101')) THEN Val END)
,Tuesday = MAX(CASE WHEN weekday = datename(dw, dateadd(dd, 3 - 2, '19000101')) THEN Val END)
,Wednesday = MAX(CASE WHEN weekday = datename(dw, dateadd(dd, 4 - 2, '19000101')) THEN Val END)
,Thursday = MAX(CASE WHEN weekday = datename(dw, dateadd(dd, 5 - 2, '19000101')) THEN Val END)
,Friday = MAX(CASE WHEN weekday = datename(dw, dateadd(dd, 6 - 2, '19000101')) THEN Val END)
,Saturday = MAX(CASE WHEN weekday = datename(dw, dateadd(dd, 7 - 2, '19000101')) THEN Val END)
FROM dbo.TestGrid
CROSS APPLY (
VALUES(High, 'High', DATENAME(dw, CAST(DateID AS CHAR(8))))
,(Low, 'Low', DATENAME(dw, CAST(DateID AS CHAR(8))))) a(Val, Type, weekday)
GROUP BY CompanyName, Type;
January 2, 2013 at 2:30 pm
Thanks guys, i've tried both and both get the same results as i expected. I thought i had use cross apply just wasn't too sure how to use it to get what i expected.
To answer the question about why is DateID int and not datetime its an old table and data already in there. I assume its for an indexing/performance benefit and everything is based on dateid for searching? does that sound about right?
January 2, 2013 at 5:36 pm
Tava (1/2/2013)
To answer the question about why is DateID int and not datetime its an old table and data already in there. I assume its for an indexing/performance benefit and everything is based on dateid for searching? does that sound about right?
It is not the first time I've heard of someone being stuck with a legacy design. If you're in SQL 2008 and designing anew, using DATE datatype would provide the same indexing/performance benefit as what you've done. I actually doubt there would be a difference had the field been created as a DATETIME (just perhaps a little more application housekeeping to ensure that no time part is stored with it).
Lynn - Nice way to eliminate the dependency on DATEFIRST.
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?[/url]
Since random numbers are too important to be left to chance, let's generate some![/url]
Learn to understand recursive CTEs by example.[/url]
[url url=http://www.sqlservercentral.com/articles/St
January 2, 2013 at 6:02 pm
dwain.c (1/2/2013)
Tava (1/2/2013)
To answer the question about why is DateID int and not datetime its an old table and data already in there. I assume its for an indexing/performance benefit and everything is based on dateid for searching? does that sound about right?It is not the first time I've heard of someone being stuck with a legacy design. If you're in SQL 2008 and designing anew, using DATE datatype would provide the same indexing/performance benefit as what you've done. I actually doubt there would be a difference had the field been created as a DATETIME (just perhaps a little more application housekeeping to ensure that no time part is stored with it).
Lynn - Nice way to eliminate the dependency on DATEFIRST.
I don't think it works the way I expected it to, looks like it is missing part of the code due to a poor copy and past. I'll have to look at later when I get back to the apartment.
January 2, 2013 at 6:16 pm
Lynn Pettis (1/2/2013)
dwain.c (1/2/2013)
Tava (1/2/2013)
To answer the question about why is DateID int and not datetime its an old table and data already in there. I assume its for an indexing/performance benefit and everything is based on dateid for searching? does that sound about right?It is not the first time I've heard of someone being stuck with a legacy design. If you're in SQL 2008 and designing anew, using DATE datatype would provide the same indexing/performance benefit as what you've done. I actually doubt there would be a difference had the field been created as a DATETIME (just perhaps a little more application housekeeping to ensure that no time part is stored with it).
Lynn - Nice way to eliminate the dependency on DATEFIRST.
I don't think it works the way I expected it to, looks like it is missing part of the code due to a poor copy and past. I'll have to look at later when I get back to the apartment.
Hehe. I didn't try to run it but understood what you were trying to do. I think you meant this (in the CASE statements):
SELECT datename(dw, dateadd(day, 1 - 2, '19000101')) -- for Sunday
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?[/url]
Since random numbers are too important to be left to chance, let's generate some![/url]
Learn to understand recursive CTEs by example.[/url]
[url url=http://www.sqlservercentral.com/articles/St
January 2, 2013 at 7:05 pm
dwain.c (1/2/2013)
Lynn Pettis (1/2/2013)
dwain.c (1/2/2013)
Tava (1/2/2013)
To answer the question about why is DateID int and not datetime its an old table and data already in there. I assume its for an indexing/performance benefit and everything is based on dateid for searching? does that sound about right?It is not the first time I've heard of someone being stuck with a legacy design. If you're in SQL 2008 and designing anew, using DATE datatype would provide the same indexing/performance benefit as what you've done. I actually doubt there would be a difference had the field been created as a DATETIME (just perhaps a little more application housekeeping to ensure that no time part is stored with it).
Lynn - Nice way to eliminate the dependency on DATEFIRST.
I don't think it works the way I expected it to, looks like it is missing part of the code due to a poor copy and past. I'll have to look at later when I get back to the apartment.
Hehe. I didn't try to run it but understood what you were trying to do. I think you meant this (in the CASE statements):
SELECT datename(dw, dateadd(day, 1 - 2, '19000101')) -- for Sunday
Should also take care of language differences.
January 3, 2013 at 1:02 am
i tried it with PIVOT but its more resource intensive (as compared to other provided solution ) . can we avoid UNION here
SELECT CompanyName, 'Low' as Type,
[Sunday], [Monday], [tuesday], [wednesday], [thursday],[Friday],[Saturday]
FROM
(
select
CompanyName,
Low,
CASE
WHEN DATEPART(dw, CAST(DateID AS CHAR(8))) = 1 THEN 'Sunday'
WHEN DATEPART(dw, CAST(DateID AS CHAR(8))) = 2 THEN 'Monday'
WHEN DATEPART(dw, CAST(DateID AS CHAR(8))) = 3 THEN 'tuesday'
WHEN DATEPART(dw, CAST(DateID AS CHAR(8))) = 4 THEN 'wednesday'
WHEN DATEPART(dw, CAST(DateID AS CHAR(8))) = 5 THEN 'thursday'
WHEN DATEPART(dw, CAST(DateID AS CHAR(8))) = 6 THEN 'Friday'
WHEN DATEPART(dw, CAST(DateID AS CHAR(8))) = 7 THEN 'Saturday'
END as WeekDays
from [TestGrid]
) AS SourceTable
PIVOT
(
SUM(Low)
FOR WeekDays IN ([Sunday], [Monday], [tuesday], [wednesday], [thursday],[Friday],[Saturday])
) AS PivotTable
UNION
SELECT CompanyName, 'High' as Type,
[Sunday], [Monday], [tuesday], [wednesday], [thursday],[Friday],[Saturday]
FROM
(
select
CompanyName,
High,
CASE
WHEN DATEPART(dw, CAST(DateID AS CHAR(8))) = 1 THEN 'Sunday'
WHEN DATEPART(dw, CAST(DateID AS CHAR(8))) = 2 THEN 'Monday'
WHEN DATEPART(dw, CAST(DateID AS CHAR(8))) = 3 THEN 'tuesday'
WHEN DATEPART(dw, CAST(DateID AS CHAR(8))) = 4 THEN 'wednesday'
WHEN DATEPART(dw, CAST(DateID AS CHAR(8))) = 5 THEN 'thursday'
WHEN DATEPART(dw, CAST(DateID AS CHAR(8))) = 6 THEN 'Friday'
WHEN DATEPART(dw, CAST(DateID AS CHAR(8))) = 7 THEN 'Saturday'
END as WeekDays
from [TestGrid]
) AS SourceTable
PIVOT
(
SUM(High)
FOR WeekDays IN ([Sunday], [Monday], [tuesday], [wednesday], [thursday],[Friday],[Saturday])
) AS PivotTable
-------Bhuvnesh----------
I work only to learn Sql Server...though my company pays me for getting their stuff done;-)
January 4, 2013 at 3:19 am
dwain.c (1/1/2013)
CROSS APPLY (
VALUES(High, 'High', DATEPART(dw, CAST(DateID AS CHAR(8))))
,(Low, 'Low', DATEPART(dw, CAST(DateID AS CHAR(8))))) a(Val, Type, weekday)
GROUP BY CompanyName, Type
dwain , can you please explain above sql code , i am finding it hard to understand :sick:
-------Bhuvnesh----------
I work only to learn Sql Server...though my company pays me for getting their stuff done;-)
January 4, 2013 at 3:35 am
Bhuvnesh (1/4/2013)
dwain.c (1/1/2013)
CROSS APPLY (
VALUES(High, 'High', DATEPART(dw, CAST(DateID AS CHAR(8))))
,(Low, 'Low', DATEPART(dw, CAST(DateID AS CHAR(8))))) a(Val, Type, weekday)
GROUP BY CompanyName, Type
dwain , can you please explain above sql code , i am finding it hard to understand :sick:
The easiest would be for you to read the first article linked into my signature. It compares various examples to UNPIVOT.
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?[/url]
Since random numbers are too important to be left to chance, let's generate some![/url]
Learn to understand recursive CTEs by example.[/url]
[url url=http://www.sqlservercentral.com/articles/St
January 4, 2013 at 3:53 am
Bhuvnesh (1/3/2013)
i tried it with PIVOT but its more resource intensive (as compared to other provided solution ) . can we avoid UNION here
SELECT CompanyName, 'Low' as Type,
[Sunday], [Monday], [tuesday], [wednesday], [thursday],[Friday],[Saturday]
FROM
(
select
CompanyName,
Low,
CASE
WHEN DATEPART(dw, CAST(DateID AS CHAR(8))) = 1 THEN 'Sunday'
WHEN DATEPART(dw, CAST(DateID AS CHAR(8))) = 2 THEN 'Monday'
WHEN DATEPART(dw, CAST(DateID AS CHAR(8))) = 3 THEN 'tuesday'
WHEN DATEPART(dw, CAST(DateID AS CHAR(8))) = 4 THEN 'wednesday'
WHEN DATEPART(dw, CAST(DateID AS CHAR(8))) = 5 THEN 'thursday'
WHEN DATEPART(dw, CAST(DateID AS CHAR(8))) = 6 THEN 'Friday'
WHEN DATEPART(dw, CAST(DateID AS CHAR(8))) = 7 THEN 'Saturday'
END as WeekDays
from [TestGrid]
) AS SourceTable
PIVOT
(
SUM(Low)
FOR WeekDays IN ([Sunday], [Monday], [tuesday], [wednesday], [thursday],[Friday],[Saturday])
) AS PivotTable
UNION
SELECT CompanyName, 'High' as Type,
[Sunday], [Monday], [tuesday], [wednesday], [thursday],[Friday],[Saturday]
FROM
(
select
CompanyName,
High,
CASE
WHEN DATEPART(dw, CAST(DateID AS CHAR(8))) = 1 THEN 'Sunday'
WHEN DATEPART(dw, CAST(DateID AS CHAR(8))) = 2 THEN 'Monday'
WHEN DATEPART(dw, CAST(DateID AS CHAR(8))) = 3 THEN 'tuesday'
WHEN DATEPART(dw, CAST(DateID AS CHAR(8))) = 4 THEN 'wednesday'
WHEN DATEPART(dw, CAST(DateID AS CHAR(8))) = 5 THEN 'thursday'
WHEN DATEPART(dw, CAST(DateID AS CHAR(8))) = 6 THEN 'Friday'
WHEN DATEPART(dw, CAST(DateID AS CHAR(8))) = 7 THEN 'Saturday'
END as WeekDays
from [TestGrid]
) AS SourceTable
PIVOT
(
SUM(High)
FOR WeekDays IN ([Sunday], [Monday], [tuesday], [wednesday], [thursday],[Friday],[Saturday])
) AS PivotTable
You do know that your code is also sensitive to changes in DATEFIRST, correct?
January 4, 2013 at 5:59 am
Bhuvnesh,
CROSS APPLY (
VALUES(High, 'High', DATEPART(dw, CAST(DateID AS CHAR(8))))
,(Low, 'Low', DATEPART(dw, CAST(DateID AS CHAR(8))))) a (Val, Type, weekday)
GROUP BY CompanyName, Type
is similar to
CROSS APPLY (
select High as val , 'High' as Type , DATEPART(dw, CAST(DateID AS CHAR(8))) as Weekday
union all
select Low as val, 'Low' as Type , DATEPART(dw, CAST(DateID AS CHAR(8)))
) a
GROUP BY CompanyName, Type
Hope you understood..
Thanks,
Saurabh
January 4, 2013 at 5:52 pm
Saurv (1/4/2013)
Bhuvnesh,
CROSS APPLY (
VALUES(High, 'High', DATEPART(dw, CAST(DateID AS CHAR(8))))
,(Low, 'Low', DATEPART(dw, CAST(DateID AS CHAR(8))))) a (Val, Type, weekday)
GROUP BY CompanyName, Type
is similar to
CROSS APPLY (
select High as val , 'High' as Type , DATEPART(dw, CAST(DateID AS CHAR(8))) as Weekday
union all
select Low as val, 'Low' as Type , DATEPART(dw, CAST(DateID AS CHAR(8)))
) a
GROUP BY CompanyName, Type
Hope you understood..
Thanks,
Saurabh
I believe that CAV offers a higher degree of potential parallelization. Read the discussion thread on the article for more information on that.
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?[/url]
Since random numbers are too important to be left to chance, let's generate some![/url]
Learn to understand recursive CTEs by example.[/url]
[url url=http://www.sqlservercentral.com/articles/St
May 5, 2014 at 9:27 pm
Sounds like quite a complicated question to me. However, I am quite interested on this grid layout problem. I've had some experience on the winforms grid control, however I am quite new to this SQL environment, this question relieved my curiosity.
Viewing 15 posts - 1 through 14 (of 14 total)
You must be logged in to reply to this topic. Login to reply