Please start any new threads on our new site at https://forums.sqlteam.com. We've got lots of great SQL Server experts to answer whatever question you can come up with.

 All Forums
 General SQL Server Forums
 New to SQL Server Programming
 Dividing a Database column into two

Author  Topic 

sundayose
Starting Member

21 Posts

Posted - 2013-04-29 : 03:58:00

Please open the image and see my problem. It's a table so I failed to type it or insert it here.
http://i.stack.imgur.com/5QbjH.png

Thank you.

visakh16
Very Important crosS Applying yaK Herder

52326 Posts

Posted - 2013-04-29 : 04:03:49
[code]
SELECT int_Client_ID,
MAX(CASE WHEN Seq = 1 THEN Str_Code END) AS A1,
MAX(CASE WHEN Seq = 2 THEN Str_Code END) AS A2
FROM
(
SELECT ROW_NUMBER() OVER (PARTITION BY int_Client_ID ORDER BY Str_Code) AS Seq,*
FROM Table
)t
GROUP BY int_Client_ID
[/code]

------------------------------------------------------------------------------------------------------
SQL Server MVP
http://visakhm.blogspot.com/
https://www.facebook.com/VmBlogs
Go to Top of Page

sundayose
Starting Member

21 Posts

Posted - 2013-04-29 : 04:18:53
THANK YOU. IT HAS WORKED

quote:
Originally posted by visakh16


SELECT int_Client_ID,
MAX(CASE WHEN Seq = 1 THEN Str_Code END) AS A1,
MAX(CASE WHEN Seq = 2 THEN Str_Code END) AS A2
FROM
(
SELECT ROW_NUMBER() OVER (PARTITION BY int_Client_ID ORDER BY Str_Code) AS Seq,*
FROM Table
)t
GROUP BY int_Client_ID


------------------------------------------------------------------------------------------------------
SQL Server MVP
http://visakhm.blogspot.com/
https://www.facebook.com/VmBlogs


Go to Top of Page

visakh16
Very Important crosS Applying yaK Herder

52326 Posts

Posted - 2013-04-29 : 04:20:21
ROW_NUMBER with partition will divide table data into groups based on value of int_Client_ID column. then inside each group it numbers records based on order of Str_Code field value. so all with A1 gets 1 and A2 gets 2. then in my conditional statement i take value with 1 first (A1 value) and 2 next (A2 value) for each group which will give you your desired result.

------------------------------------------------------------------------------------------------------
SQL Server MVP
http://visakhm.blogspot.com/
https://www.facebook.com/VmBlogs
Go to Top of Page

sundayose
Starting Member

21 Posts

Posted - 2013-04-29 : 04:40:22
THANK AGAIN.

WOULD YOU PLEASE HELP ME AGAIN. EACH OF THOSE CODES HAS a Visit date and Submission Dates i.e (dt_Vdate & dt_Sdate). I need to know how I could modify the code so that every after the code column, the next two column are date columns.
If the code is null then the date will also be null.

I have tried adding dt_Vdate and dt_Sdate after int_Client_ID in the code under the select Statement but I get an error "column 't.dt_Vdate' is invalid in the select list because it is not contained in either an aggregate function or the GROUP BY clause.
"

Thanks.

quote:
Originally posted by visakh16

ROW_NUMBER with partition will divide table data into groups based on value of int_Client_ID column. then inside each group it numbers records based on order of Str_Code field value. so all with A1 gets 1 and A2 gets 2. then in my conditional statement i take value with 1 first (A1 value) and 2 next (A2 value) for each group which will give you your desired result.

------------------------------------------------------------------------------------------------------
SQL Server MVP
http://visakhm.blogspot.com/
https://www.facebook.com/VmBlogs


Go to Top of Page

visakh16
Very Important crosS Applying yaK Herder

52326 Posts

Posted - 2013-04-29 : 04:51:21
sounds like this


SELECT int_Client_ID,
MAX(CASE WHEN Seq = 1 THEN Str_Code END) AS A1,
MAX(CASE WHEN Seq = 1 THEN dt_Vdate END) AS A1Vdate,
MAX(CASE WHEN Seq = 1 THEN dt_Sdate END) AS A1Sdate,
MAX(CASE WHEN Seq = 2 THEN Str_Code END) AS A2,
MAX(CASE WHEN Seq = 2 THEN dt_Vdate END) AS A2Vdate,
MAX(CASE WHEN Seq = 2 THEN dt_Sdate END) AS A2Sdate
FROM
(
SELECT ROW_NUMBER() OVER (PARTITION BY int_Client_ID ORDER BY Str_Code) AS Seq,*
FROM Table
)t
GROUP BY int_Client_ID


if this doesnt work post how dates are existing as in initial question with some data and show your required output

------------------------------------------------------------------------------------------------------
SQL Server MVP
http://visakhm.blogspot.com/
https://www.facebook.com/VmBlogs
Go to Top of Page

visakh16
Very Important crosS Applying yaK Herder

52326 Posts

Posted - 2013-04-29 : 05:48:21
welcome

------------------------------------------------------------------------------------------------------
SQL Server MVP
http://visakhm.blogspot.com/
https://www.facebook.com/VmBlogs
Go to Top of Page

sundayose
Starting Member

21 Posts

Posted - 2013-04-29 : 05:51:50
THANK YOU IT HAS WORKED. BUT IT ALSO POPULATES DATES EVEN WHEN THE CODE IS NULL.

quote:
Originally posted by visakh16

sounds like this


SELECT int_Client_ID,
MAX(CASE WHEN Seq = 1 THEN Str_Code END) AS A1,
MAX(CASE WHEN Seq = 1 THEN dt_Vdate END) AS A1Vdate,
MAX(CASE WHEN Seq = 1 THEN dt_Sdate END) AS A1Sdate,
MAX(CASE WHEN Seq = 2 THEN Str_Code END) AS A2,
MAX(CASE WHEN Seq = 2 THEN dt_Vdate END) AS A2Vdate,
MAX(CASE WHEN Seq = 2 THEN dt_Sdate END) AS A2Sdate
FROM
(
SELECT ROW_NUMBER() OVER (PARTITION BY int_Client_ID ORDER BY Str_Code) AS Seq,*
FROM Table
)t
GROUP BY int_Client_ID


if this doesnt work post how dates are existing as in initial question with some data and show your required output

------------------------------------------------------------------------------------------------------
SQL Server MVP
http://visakhm.blogspot.com/
https://www.facebook.com/VmBlogs


Go to Top of Page

visakh16
Very Important crosS Applying yaK Herder

52326 Posts

Posted - 2013-04-29 : 05:55:10
what does that mean? can you illustrate an example?

------------------------------------------------------------------------------------------------------
SQL Server MVP
http://visakhm.blogspot.com/
https://www.facebook.com/VmBlogs
Go to Top of Page

sundayose
Starting Member

21 Posts

Posted - 2013-04-29 : 06:03:53
I had made some typing error but it's working as expected.

Thank you.

quote:
Originally posted by visakh16

what does that mean? can you illustrate an example?

------------------------------------------------------------------------------------------------------
SQL Server MVP
http://visakhm.blogspot.com/
https://www.facebook.com/VmBlogs


Go to Top of Page

visakh16
Very Important crosS Applying yaK Herder

52326 Posts

Posted - 2013-04-29 : 06:08:08
quote:
Originally posted by sundayose

I had made some typing error but it's working as expected.

Thank you.

quote:
Originally posted by visakh16

what does that mean? can you illustrate an example?

------------------------------------------------------------------------------------------------------
SQL Server MVP
http://visakhm.blogspot.com/
https://www.facebook.com/VmBlogs





Ok...glad that you got it sorted out!

------------------------------------------------------------------------------------------------------
SQL Server MVP
http://visakhm.blogspot.com/
https://www.facebook.com/VmBlogs
Go to Top of Page

sundayose
Starting Member

21 Posts

Posted - 2013-04-29 : 06:19:55
I have another Table called Delivery, I need to add the codes in this table adjacent to the first out put where the client ID is the same in both tables.
The codes in the Delivery are of the format (G01D1,G01D2) and (G02D1,G02D1)

quote:
Originally posted by visakh16

quote:
Originally posted by sundayose

I had made some typing error but it's working as expected.

Thank you.

quote:
Originally posted by visakh16

what does that mean? can you illustrate an example?

------------------------------------------------------------------------------------------------------
SQL Server MVP
http://visakhm.blogspot.com/
https://www.facebook.com/VmBlogs





Ok...glad that you got it sorted out!

------------------------------------------------------------------------------------------------------
SQL Server MVP
http://visakhm.blogspot.com/
https://www.facebook.com/VmBlogs


Go to Top of Page

sundayose
Starting Member

21 Posts

Posted - 2013-04-29 : 06:22:36
I have a second table called Delivery, with codes (G01D1,G01D2),(G02D1,G02D2)
I need to add them to the first output adjacent where the client ID in both tables is the same.

quote:
Originally posted by visakh16

quote:
Originally posted by sundayose

I had made some typing error but it's working as expected.

Thank you.

quote:
Originally posted by visakh16

what does that mean? can you illustrate an example?

------------------------------------------------------------------------------------------------------
SQL Server MVP
http://visakhm.blogspot.com/
https://www.facebook.com/VmBlogs





Ok...glad that you got it sorted out!

------------------------------------------------------------------------------------------------------
SQL Server MVP
http://visakhm.blogspot.com/
https://www.facebook.com/VmBlogs


Go to Top of Page

visakh16
Very Important crosS Applying yaK Herder

52326 Posts

Posted - 2013-04-29 : 06:29:29
show how the data is in second table. does all global codes exist in same row or in separate rows for the same clientid?

------------------------------------------------------------------------------------------------------
SQL Server MVP
http://visakhm.blogspot.com/
https://www.facebook.com/VmBlogs
Go to Top of Page

sundayose
Starting Member

21 Posts

Posted - 2013-04-29 : 06:35:46
The second table has It's ID, client_D (similar to that in the first table) but the client id is from the client Master for both tables and the code.

Expected final output

1 G01A1 G01A2 G01D1
2 G02A1 G02A2 G02D1
3 G03A1 G03A2 G03D1


quote:
Originally posted by visakh16

show how the data is in second table. does all global codes exist in same row or in separate rows for the same clientid?

------------------------------------------------------------------------------------------------------
SQL Server MVP
http://visakhm.blogspot.com/
https://www.facebook.com/VmBlogs


Go to Top of Page

visakh16
Very Important crosS Applying yaK Herder

52326 Posts

Posted - 2013-04-29 : 06:41:02
then its a straightforward join

SELECT t.int_Client_ID,
MAX(CASE WHEN Seq = 1 THEN t.Str_Code END) AS A1,
MAX(CASE WHEN Seq = 1 THEN t.dt_Vdate END) AS A1Vdate,
MAX(CASE WHEN Seq = 1 THEN t.dt_Sdate END) AS A1Sdate,
MAX(CASE WHEN Seq = 2 THEN t.Str_Code END) AS A2,
MAX(CASE WHEN Seq = 2 THEN t.dt_Vdate END) AS A2Vdate,
MAX(CASE WHEN Seq = 2 THEN t.dt_Sdate END) AS A2Sdate,
MAX(d.Code) AS GlobalCode
FROM
(
SELECT ROW_NUMBER() OVER (PARTITION BY int_Client_ID ORDER BY Str_Code) AS Seq,*
FROM Table
)t
INNER JOIN Delivery d
ON d.Cleient_ID = t.Client_ID
GROUP BY t.int_Client_ID



------------------------------------------------------------------------------------------------------
SQL Server MVP
http://visakhm.blogspot.com/
https://www.facebook.com/VmBlogs
Go to Top of Page

sundayose
Starting Member

21 Posts

Posted - 2013-04-30 : 06:07:13
THANK YOU. ALL WORKED WELL.

quote:
Originally posted by visakh16

then its a straightforward join

SELECT t.int_Client_ID,
MAX(CASE WHEN Seq = 1 THEN t.Str_Code END) AS A1,
MAX(CASE WHEN Seq = 1 THEN t.dt_Vdate END) AS A1Vdate,
MAX(CASE WHEN Seq = 1 THEN t.dt_Sdate END) AS A1Sdate,
MAX(CASE WHEN Seq = 2 THEN t.Str_Code END) AS A2,
MAX(CASE WHEN Seq = 2 THEN t.dt_Vdate END) AS A2Vdate,
MAX(CASE WHEN Seq = 2 THEN t.dt_Sdate END) AS A2Sdate,
MAX(d.Code) AS GlobalCode
FROM
(
SELECT ROW_NUMBER() OVER (PARTITION BY int_Client_ID ORDER BY Str_Code) AS Seq,*
FROM Table
)t
INNER JOIN Delivery d
ON d.Cleient_ID = t.Client_ID
GROUP BY t.int_Client_ID



------------------------------------------------------------------------------------------------------
SQL Server MVP
http://visakhm.blogspot.com/
https://www.facebook.com/VmBlogs


Go to Top of Page

visakh16
Very Important crosS Applying yaK Herder

52326 Posts

Posted - 2013-04-30 : 06:08:08
welcome

------------------------------------------------------------------------------------------------------
SQL Server MVP
http://visakhm.blogspot.com/
https://www.facebook.com/VmBlogs
Go to Top of Page
   

- Advertisement -