Group By Character Name and list all Scene numbers

signup

New Member
Joined
Feb 15, 2018
Messages
42
Office Version
  1. 2019
Platform
  1. Windows
Hello All, Hope you are doing Fine.

I have Excel data as shown in the below table. Can anyone help me to get the desired output?

SCENE NUMBER
CHARACTER NAME
E01 SC 01​
MICHAEL
E01 SC 01​
JACK
E01 SC 01​
ELIZABETH
E01 SC 02​
JOHN
E01 SC 02​
MICHAEL
E01 SC 03​
JACK
E01 SC 03​
SAMANTHA
E01 SC 03​
MICHAEL
E01 SC 03​
LOGAN​
E01 SC 04​
ELIZABETH
E01 SC 04​
SAMANTHA
E01 SC 04​
LOGAN​
E01 SC 05​
MICHAEL
E01 SC 05​
JACK
E02 SC 01​
EVAN​
E02 SC 01​
ELIZABETH
E02 SC 01​
JOHN
E02 SC 02​
MICHAEL
E02 SC 02​
SAMANTHA
E02 SC 03​
ANGEL​
E02 SC 03​
LOGAN​
E02 SC 04​
JOHN
E02 SC 04​
MICHAEL
E02 SC 05​
JACK
E02 SC 06​
MICHAEL
E02 SC 07​
ANGEL​
E02 SC 07​
LOGAN​
E02 SC 08​
SAMANTHA
E02 SC 09​
JACK
E02 SC 09​
JOHN
E02 SC 10​
MICHAEL

In the above sheet, I have character names from the scene. I need to prepare Character-wise scene numbers for my project. So, by making characters unique I need to create a list of scene numbers.

EXPECTED OUTPUT : (Note: Below output is Just to understand the requirement only but not precisely like this)

I need to get all the scene numbers list for the character.

MICHAEL -
E01 SC 01, E01 SC 02, E01 SC 03, E01 SC 05, E02 SC 02, E02 SC 04, E02 SC 06, E02 SC 10
JACK - E01 SC 01, E01 SC 03, E01 SC 05, E02 SC 05, E02 SC 09
ELIZABETH - E01 SC 01, E01 SC 04, E02 SC 01
JOHN - E01 SC 02, E02 SC 01, E02 SC 04, E02 SC 09
SAMANTHA - E01 SC 03, E01 SC 04, E02 SC 02, E02 SC 08
LOGAN - E01 SC 03, E01 SC 04, E02 SC 03, E02 SC 07
EVAN - E02 SC 01
ANGEL - E02 SC 03, E02 SC 07

If there is any way to achieve this, Please help me.

Thanks in advance!
 

Excel Facts

Select a hidden cell
Somehide hide payroll data in column G? Press F5. Type G1. Enter. Look in formula bar while you arrow down through G.
What version of Excel are you using?

I suggest that you update your Account details (click your user name at the top right of the forum) so helpers always know what Excel version(s) & platform(s) you are using as the best solution often varies by version. (Don’t forget to scroll down & ‘Save’)
 
Upvote 0
SCENE NUMBERCHARACTER NAMECHARACTER NAMESCENE NUMBER
E01 SC 01MICHAELMICHAELE01 SC 01,E01 SC 02,E01 SC 03,E01 SC 05,E02 SC 02,E02 SC 04,E02 SC 06,E02 SC 10
E01 SC 01JACKJACKE01 SC 01,E01 SC 03,E01 SC 05,E02 SC 05,E02 SC 09
E01 SC 01ELIZABETHELIZABETHE01 SC 01,E01 SC 04,E02 SC 01
E01 SC 02JOHNJOHNE01 SC 02,E02 SC 01,E02 SC 04,E02 SC 09
E01 SC 02MICHAELSAMANTHAE01 SC 03,E01 SC 04,E02 SC 02,E02 SC 08
E01 SC 03JACKLOGANE01 SC 03,E01 SC 04,E02 SC 03,E02 SC 07
E01 SC 03SAMANTHAEVANE02 SC 01
E01 SC 03MICHAELANGELE02 SC 03,E02 SC 07
E01 SC 03LOGAN
E01 SC 04ELIZABETH
E01 SC 04SAMANTHA
E01 SC 04LOGAN
E01 SC 05MICHAEL
E01 SC 05JACK
E02 SC 01EVAN
E02 SC 01ELIZABETH
E02 SC 01JOHN
E02 SC 02MICHAEL
E02 SC 02SAMANTHA
E02 SC 03ANGEL
E02 SC 03LOGAN
E02 SC 04JOHN
E02 SC 04MICHAEL
E02 SC 05JACK
E02 SC 06MICHAEL
E02 SC 07ANGEL
E02 SC 07LOGAN
E02 SC 08SAMANTHA
E02 SC 09JACK
E02 SC 09JOHN
E02 SC 10MICHAEL

Power Query:
let
    Source = Excel.CurrentWorkbook(){[Name="Table1"]}[Content],
    Group = Table.Group(Source, {"CHARACTER NAME"}, {{"Count", each _, type table}}),
    List = Table.AddColumn(Group, "SCENE NUMBER", each [Count][SCENE NUMBER]),
    Extract = Table.TransformColumns(List, {"SCENE NUMBER", each Text.Combine(List.Transform(_, Text.From), ","), type text})
in
    Extract
 
Upvote 0
What version of Excel are you using?

I suggest that you update your Account details (click your user name at the top right of the forum) so helpers always know what Excel version(s) & platform(s) you are using as the best solution often varies by version. (Don’t forget to scroll down & ‘Save’)
Hello, Thanks for the advice. I have updated the profile now.
 
Upvote 0
SCENE NUMBERCHARACTER NAMECHARACTER NAMESCENE NUMBER
E01 SC 01MICHAELMICHAELE01 SC 01,E01 SC 02,E01 SC 03,E01 SC 05,E02 SC 02,E02 SC 04,E02 SC 06,E02 SC 10
E01 SC 01JACKJACKE01 SC 01,E01 SC 03,E01 SC 05,E02 SC 05,E02 SC 09
E01 SC 01ELIZABETHELIZABETHE01 SC 01,E01 SC 04,E02 SC 01
E01 SC 02JOHNJOHNE01 SC 02,E02 SC 01,E02 SC 04,E02 SC 09
E01 SC 02MICHAELSAMANTHAE01 SC 03,E01 SC 04,E02 SC 02,E02 SC 08
E01 SC 03JACKLOGANE01 SC 03,E01 SC 04,E02 SC 03,E02 SC 07
E01 SC 03SAMANTHAEVANE02 SC 01
E01 SC 03MICHAELANGELE02 SC 03,E02 SC 07
E01 SC 03LOGAN
E01 SC 04ELIZABETH
E01 SC 04SAMANTHA
E01 SC 04LOGAN
E01 SC 05MICHAEL
E01 SC 05JACK
E02 SC 01EVAN
E02 SC 01ELIZABETH
E02 SC 01JOHN
E02 SC 02MICHAEL
E02 SC 02SAMANTHA
E02 SC 03ANGEL
E02 SC 03LOGAN
E02 SC 04JOHN
E02 SC 04MICHAEL
E02 SC 05JACK
E02 SC 06MICHAEL
E02 SC 07ANGEL
E02 SC 07LOGAN
E02 SC 08SAMANTHA
E02 SC 09JACK
E02 SC 09JOHN
E02 SC 10MICHAEL

Power Query:
let
    Source = Excel.CurrentWorkbook(){[Name="Table1"]}[Content],
    Group = Table.Group(Source, {"CHARACTER NAME"}, {{"Count", each _, type table}}),
    List = Table.AddColumn(Group, "SCENE NUMBER", each [Count][SCENE NUMBER]),
    Extract = Table.TransformColumns(List, {"SCENE NUMBER", each Text.Combine(List.Transform(_, Text.From), ","), type text})
in
    Extract
Thanks for the prompt response, I will check this code on my data and let me get back to you. Hope this won't affect on large size of the data as I have almost 3000 rows in my worksheet..
 
Upvote 0
I have updated the profile now.
Thanks for that.
With a formula
+Fluff 1.xlsm
ABCDE
1SCENE NUMBERCHARACTER NAME
2E01 SC 01MICHAELMICHAELE01 SC 01, E01 SC 02, E01 SC 03, E01 SC 05, E02 SC 02, E02 SC 04, E02 SC 06, E02 SC 10
3E01 SC 01JACKELIZABETHE01 SC 01, E01 SC 04, E02 SC 01
4E01 SC 01ELIZABETHJACKE01 SC 01, E01 SC 03, E01 SC 05, E02 SC 05, E02 SC 09
5E01 SC 02JOHNSAMANTHAE01 SC 03, E01 SC 04, E02 SC 02, E02 SC 08
6E01 SC 02MICHAELJOHNE01 SC 02, E02 SC 01, E02 SC 04, E02 SC 09
7E01 SC 03JACKANGELE02 SC 03, E02 SC 07
8E01 SC 03SAMANTHA  
9E01 SC 03MICHAEL  
10E01 SC 03LOGAN  
11E01 SC 04ELIZABETH  
12E01 SC 04SAMANTHA  
13E01 SC 04LOGAN
14E01 SC 05MICHAEL
15E01 SC 05JACK
16E02 SC 01EVAN
17E02 SC 01ELIZABETH
18E02 SC 01JOHN
19E02 SC 02MICHAEL
20E02 SC 02SAMANTHA
21E02 SC 03ANGEL
22E02 SC 03LOGAN
23E02 SC 04JOHN
24E02 SC 04MICHAEL
25E02 SC 05JACK
26E02 SC 06MICHAEL
27E02 SC 07ANGEL
28E02 SC 07LOGAN
29E02 SC 08SAMANTHA
30E02 SC 09JACK
31E02 SC 09JOHN
32E02 SC 10MICHAEL
33
34
Main
Cell Formulas
RangeFormula
D2:D12D2=IFERROR(INDEX($B$2:$B$4000,AGGREGATE(15,6,(ROW($B$2:$B$4000)-ROW($B$2)+1)/(ISNA(MATCH($B$2:$B$4000,D$1:D1,0)))/($B$2:$B$4000<>""),ROWS(D$2:D2))),"")
E2:E12E2=IF(D2="","",TEXTJOIN(", ",,IF($B$2:$B$8552=D2,$A$2:$A$8552,"")))
Press CTRL+SHIFT+ENTER to enter array formulas.
 
Upvote 0
SCENE NUMBERCHARACTER NAMECHARACTER NAMESCENE NUMBER
E01 SC 01MICHAELMICHAELE01 SC 01,E01 SC 02,E01 SC 03,E01 SC 05,E02 SC 02,E02 SC 04,E02 SC 06,E02 SC 10
E01 SC 01JACKJACKE01 SC 01,E01 SC 03,E01 SC 05,E02 SC 05,E02 SC 09
E01 SC 01ELIZABETHELIZABETHE01 SC 01,E01 SC 04,E02 SC 01
E01 SC 02JOHNJOHNE01 SC 02,E02 SC 01,E02 SC 04,E02 SC 09
E01 SC 02MICHAELSAMANTHAE01 SC 03,E01 SC 04,E02 SC 02,E02 SC 08
E01 SC 03JACKLOGANE01 SC 03,E01 SC 04,E02 SC 03,E02 SC 07
E01 SC 03SAMANTHAEVANE02 SC 01
E01 SC 03MICHAELANGELE02 SC 03,E02 SC 07
E01 SC 03LOGAN
E01 SC 04ELIZABETH
E01 SC 04SAMANTHA
E01 SC 04LOGAN
E01 SC 05MICHAEL
E01 SC 05JACK
E02 SC 01EVAN
E02 SC 01ELIZABETH
E02 SC 01JOHN
E02 SC 02MICHAEL
E02 SC 02SAMANTHA
E02 SC 03ANGEL
E02 SC 03LOGAN
E02 SC 04JOHN
E02 SC 04MICHAEL
E02 SC 05JACK
E02 SC 06MICHAEL
E02 SC 07ANGEL
E02 SC 07LOGAN
E02 SC 08SAMANTHA
E02 SC 09JACK
E02 SC 09JOHN
E02 SC 10MICHAEL

Power Query:
let
    Source = Excel.CurrentWorkbook(){[Name="Table1"]}[Content],
    Group = Table.Group(Source, {"CHARACTER NAME"}, {{"Count", each _, type table}}),
    List = Table.AddColumn(Group, "SCENE NUMBER", each [Count][SCENE NUMBER]),
    Extract = Table.TransformColumns(List, {"SCENE NUMBER", each Text.Combine(List.Transform(_, Text.From), ","), type text})
in
    Extract
If you don't mind may I know how to run this code on my Excel 2019? I tried to find the power query but no luck..
 
Upvote 0
If you would prefer a macro
VBA Code:
Sub signup()
   Dim Cl As Range
   Dim Dic As Object
   
   Set Dic = CreateObject("scripting.dictionary")
   With Sheets("Master")
      For Each Cl In .Range("B2", .Range("B" & Rows.Count).End(xlUp))
         If Not Dic.Exists(Cl.Value) Then
            Dic.Add Cl.Value, Cl.Offset(, -1).Value
         Else
            Dic(Cl.Value) = Dic(Cl.Value) & ", " & Cl.Offset(, -1).Value
         End If
      Next Cl
      .Range("D2").Resize(Dic.Count, 2).Value = Application.Transpose(Array(Dic.keys, Dic.items))
   End With
End Sub
Change sheet name to suit.
 
Upvote 0
If you don't mind may I know how to run this code on my Excel 2019? I tried to find the power query but no luck..
Power Query aka Get&Transform
  • Data tab
  • Get data
  • find From Other Sources - Blank Query and run it
  • Open Advanced Editor
  • replace code there with copied from the post
  • Done
  • Close&Load
remember that source table name should be the same as in the code (here is Table1)
Power Query is case sensitive

blankquery2019.png
 
Last edited:
Upvote 0

Forum statistics

Threads
1,223,238
Messages
6,170,939
Members
452,368
Latest member
jayp2104

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