Converting specific columns to vertical one record

dankar

Board Regular
Joined
Mar 23, 2016
Messages
113
Office Version
  1. 365
Platform
  1. Windows
I have similar to this table with many columns and thousand of rows (patients)

- as you can see each patient have 6 tests(test1 to test6) with different 6 result.
- all other columns have the same result.
- I need to switch the results from vertical to horizontal so I the table can show one record for each patient. like table2

Table 1:

Before:
FILE NO
RCVD DATE
COUNTRY
ID_NO
PID_NO
TEST
RESULT
REPORT DATE
1
5/1/2018
USA
1234567890
ABCDEFGH
TEST1
NOT TESTED
5/25/2018
1
5/1/2018
USA
1234567890
ABCDEFGH
TEST2
NOT TESED
5/25/2018
1
5/1/2018
USA
1234567890
ABCDEFGH
TEST3
POSITIVE
5/25/2018
1
5/1/2018
USA
1234567890
ABCDEFGH
FINAL RESULT
POSTTIVE
5/25/2018
1
5/1/2018
USA
1234567890
ABCDEFGH
TEST4
NOT TESTED
5/25/2018
1
5/1/2018
USA
1234567890
ABCDEFGH

TEST5
NOT TESTED
5/25/2018
1
5/1/2018
USA
1234567890
ABCDEFGH
TEST6
PENDING
5/25/2018

<tbody>
</tbody>

Table 2

After:
FILE NO
RCVD DATE
COUNTRY
ID_NO
PID_NO
TEST1
TEST2
TEST3
TEST4
TEST5
TEST6
FINAL RESULT
REPORT DATE
1
5/1/2018
USA
1234567890
ABCDEFGH
NOT TESTED
NOT TESTED
POSITIVE
NOT TESTED
NOT TESTED
PENDING
POSITIVE
5/25/2018

<tbody>
</tbody>
 

Excel Facts

Why does 9 mean SUM in SUBTOTAL?
It is because Sum is the 9th alphabetically in Average, Count, CountA, Max, Min, Product, StDev.S, StDev.P, Sum, VAR.S, VAR.P.
Re: convering spicific coulmns to vertical one record

try

FILE NORCVD DATECOUNTRYID_NOPID_NOTESTRESULTREPORT DATEFILE NORCVD DATECOUNTRYID_NOPID_NOTEST1TEST2TEST3TEST4TEST5TEST6FINALRESULTREPORT DATE
1​
05/01/2018​
USA
1.23E+09​
ABCDEFGHTEST1NOT TESTED
25/05/2018​
1​
05/01/2018​
USA
1234567890​
ABCDEFGHNOT TESTEDNOT TESEDPOSITIVENOT TESTEDNOT TESTEDPENDINGPOSTTIVE
25/05/2018​
1​
05/01/2018​
USA
1.23E+09​
ABCDEFGHTEST2NOT TESED
25/05/2018​
1​
05/01/2018​
USA
1.23E+09​
ABCDEFGHTEST3POSITIVE
25/05/2018​
1​
05/01/2018​
USA
1.23E+09​
ABCDEFGHFINALRESULTPOSTTIVE
25/05/2018​
1​
05/01/2018​
USA
1.23E+09​
ABCDEFGHTEST4NOT TESTED
25/05/2018​
1​
05/01/2018​
USA
1.23E+09​
ABCDEFGHTEST5NOT TESTED
25/05/2018​

Code:
[SIZE=1]// Table1
let
    Source = Excel.CurrentWorkbook(){[Name="Table1"]}[Content],
    Type = Table.TransformColumnTypes(Source,{{"FILE NO", Int64.Type}, {"RCVD DATE", type date}, {"COUNTRY", type text}, {"ID_NO", Int64.Type}, {"PID_NO", type text}, {"TEST", type text}, {"RESULT", type text}, {"REPORT DATE", type date}}),
    Pivot = Table.Pivot(Type, List.Distinct(Type[TEST]), "TEST", "RESULT"),
    Reorder = Table.ReorderColumns(Pivot,{"FILE NO", "RCVD DATE", "COUNTRY", "ID_NO", "PID_NO", "TEST1", "TEST2", "TEST3", "TEST4", "TEST5", "TEST6", "FINALRESULT", "REPORT DATE"})
in
    Reorder[/SIZE]
 
Last edited:
Upvote 0
Re: convering spicific coulmns to vertical one record

try

[COLOR=[URL=https://www.mrexcel.com/forum/usertag.php?do=list&action=hash&hash=FFFFFF]#FFFFFF[/URL] ]FILE NO[/COLOR]
[COLOR=[URL=https://www.mrexcel.com/forum/usertag.php?do=list&action=hash&hash=FFFFFF]#FFFFFF[/URL] ]RCVD DATE[/COLOR]
[COLOR=[URL=https://www.mrexcel.com/forum/usertag.php?do=list&action=hash&hash=FFFFFF]#FFFFFF[/URL] ]COUNTRY[/COLOR]
[COLOR=[URL=https://www.mrexcel.com/forum/usertag.php?do=list&action=hash&hash=FFFFFF]#FFFFFF[/URL] ]ID_NO[/COLOR]
[COLOR=[URL=https://www.mrexcel.com/forum/usertag.php?do=list&action=hash&hash=FFFFFF]#FFFFFF[/URL] ]PID_NO[/COLOR]
[COLOR=[URL=https://www.mrexcel.com/forum/usertag.php?do=list&action=hash&hash=FFFFFF]#FFFFFF[/URL] ]TEST[/COLOR]
[COLOR=[URL=https://www.mrexcel.com/forum/usertag.php?do=list&action=hash&hash=FFFFFF]#FFFFFF[/URL] ]RESULT[/COLOR]
[COLOR=[URL=https://www.mrexcel.com/forum/usertag.php?do=list&action=hash&hash=FFFFFF]#FFFFFF[/URL] ]REPORT DATE[/COLOR]
[COLOR=[URL=https://www.mrexcel.com/forum/usertag.php?do=list&action=hash&hash=FFFFFF]#FFFFFF[/URL] ]FILE NO[/COLOR]
[COLOR=[URL=https://www.mrexcel.com/forum/usertag.php?do=list&action=hash&hash=FFFFFF]#FFFFFF[/URL] ]RCVD DATE[/COLOR]
[COLOR=[URL=https://www.mrexcel.com/forum/usertag.php?do=list&action=hash&hash=FFFFFF]#FFFFFF[/URL] ]COUNTRY[/COLOR]
[COLOR=[URL=https://www.mrexcel.com/forum/usertag.php?do=list&action=hash&hash=FFFFFF]#FFFFFF[/URL] ]ID_NO[/COLOR]
[COLOR=[URL=https://www.mrexcel.com/forum/usertag.php?do=list&action=hash&hash=FFFFFF]#FFFFFF[/URL] ]PID_NO[/COLOR]
[COLOR=[URL=https://www.mrexcel.com/forum/usertag.php?do=list&action=hash&hash=FFFFFF]#FFFFFF[/URL] ]TEST1[/COLOR]
[COLOR=[URL=https://www.mrexcel.com/forum/usertag.php?do=list&action=hash&hash=FFFFFF]#FFFFFF[/URL] ]TEST2[/COLOR]
[COLOR=[URL=https://www.mrexcel.com/forum/usertag.php?do=list&action=hash&hash=FFFFFF]#FFFFFF[/URL] ]TEST3[/COLOR]
[COLOR=[URL=https://www.mrexcel.com/forum/usertag.php?do=list&action=hash&hash=FFFFFF]#FFFFFF[/URL] ]TEST4[/COLOR]
[COLOR=[URL=https://www.mrexcel.com/forum/usertag.php?do=list&action=hash&hash=FFFFFF]#FFFFFF[/URL] ]TEST5[/COLOR]
[COLOR=[URL=https://www.mrexcel.com/forum/usertag.php?do=list&action=hash&hash=FFFFFF]#FFFFFF[/URL] ]TEST6[/COLOR]
[COLOR=[URL=https://www.mrexcel.com/forum/usertag.php?do=list&action=hash&hash=FFFFFF]#FFFFFF[/URL] ]FINALRESULT[/COLOR]
[COLOR=[URL=https://www.mrexcel.com/forum/usertag.php?do=list&action=hash&hash=FFFFFF]#FFFFFF[/URL] ]REPORT DATE[/COLOR]

1​

05/01/2018​
USA

1.23E+09​
ABCDEFGH
TEST1
NOT TESTED

25/05/2018​

1​

05/01/2018​
USA

1234567890​
ABCDEFGH
NOT TESTED
NOT TESED
POSITIVE
NOT TESTED
NOT TESTED
PENDING
POSTTIVE

25/05/2018​

1​

05/01/2018​
USA

1.23E+09​
ABCDEFGH
TEST2
NOT TESED

25/05/2018​

1​

05/01/2018​
USA

1.23E+09​
ABCDEFGH
TEST3
POSITIVE

25/05/2018​

1​

05/01/2018​
USA

1.23E+09​
ABCDEFGH
FINALRESULT
POSTTIVE

25/05/2018​

1​

05/01/2018​
USA

1.23E+09​
ABCDEFGH
TEST4
NOT TESTED

25/05/2018​

1​

05/01/2018​
USA

1.23E+09​
ABCDEFGH
TEST5
NOT TESTED

25/05/2018​

<tbody>
</tbody>


Code:
[SIZE=1]// Table1
let
    Source = Excel.CurrentWorkbook(){[Name="Table1"]}[Content],
    Type = Table.TransformColumnTypes(Source,{{"FILE NO", Int64.Type}, {"RCVD DATE", type date}, {"COUNTRY", type text}, {"ID_NO", Int64.Type}, {"PID_NO", type text}, {"TEST", type text}, {"RESULT", type text}, {"REPORT DATE", type date}}),
    Pivot = Table.Pivot(Type, List.Distinct(Type[TEST]), "TEST", "RESULT"),
    Reorder = Table.ReorderColumns(Pivot,{"FILE NO", "RCVD DATE", "COUNTRY", "ID_NO", "PID_NO", "TEST1", "TEST2", "TEST3", "TEST4", "TEST5", "TEST6", "FINALRESULT", "REPORT DATE"})
in
    Reorder[/SIZE]

thank you for your reply and help.

will yo please explain how to apply it.

do I need to type table1 in a specific cell before the table. Thank you again
 
Upvote 0
Re: convering spicific coulmns to vertical one record

You'll need PowerQuery (Get&Transform)

your source data should be a table (Excel Table!)
then from Data tab select From Table and in a new Window (Power Query Editor) find and open Advanced Editor then replace code there with code from the post

btw. don't quote whole post !
 
Last edited:
Upvote 0
thank you and sorry for that!

I went though the steps and I got the following although "'FILE NO" is there:

Expression.Error: The column 'FILE NO' of the table wasn't found.
Details:
FILE NO
 
Upvote 0
The code is based on your example from the first post.
You can see the steps in the code, so just do them for your original data or post a real example of your source data.

Power Query is case sensitive so FILE NO is not the same as File No and check for the spaces before and after the headers

Headers must be exactly the same in the code like in source table
and Table Name must be the same as in the code (and vice versa), eg.
Code:
    Source = Excel.CurrentWorkbook(){[Name="[B][SIZE=3][COLOR="#FF0000"]Table1[/COLOR][/SIZE][/B]"]}[Content],
 
Last edited:
Upvote 0
sorry for the inconvenience.

I fixed the hears, I look silly with this..where shall I insert "Table1" to name the table :

Expression.Error: We couldn't find an Excel table named 'Table1'.
Details:
Table1
 
Upvote 0
select your whole source range then use Ctrl+T (with has headers option checked)
then go to Name Manager (Ctrl+F3) and see the name of this table then use this name in the code

if your source range is a Table then check name of this table and use it in the code
 
Last edited:
Upvote 0

Forum statistics

Threads
1,213,535
Messages
6,114,198
Members
448,554
Latest member
Gleisner2

We've detected that you are using an adblocker.

We have a great community of people providing Excel help here, but the hosting costs are enormous. You can help keep this site running by allowing ads on MrExcel.com.
Allow Ads at MrExcel

Which adblocker are you using?

Disable AdBlock

Follow these easy steps to disable AdBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the icon in the browser’s toolbar.
2)Click on the "Pause on this site" option.
Go back

Disable AdBlock Plus

Follow these easy steps to disable AdBlock Plus

1)Click on the icon in the browser’s toolbar.
2)Click on the toggle to disable it for "mrexcel.com".
Go back

Disable uBlock Origin

Follow these easy steps to disable uBlock Origin

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back

Disable uBlock

Follow these easy steps to disable uBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back
Back
Top