Complex Sort

dopydette

New Member
Joined
Jan 23, 2003
Messages
29
I have some information which is currently sorted by team number (5 in total) and execution number.
Each execution has 4 properties, Execution, Segment, Month and Duration. I need to resort the data by team number and Segment.
Whilst I know how to do this in Access, my ability to do it in Excel is somewhat limited! I hope you can help

I can not change the source data.

Here's how it looks now...
test.xls
ABCDEFGHI
1ExecutionSummaryteam1team2team3team4team5
2Execution1
3ExecutionTelevisionCommercialRadioTelevisionCommercialTelevisionCommercialTelevisionCommercial
4SegmentAspirersGrassRootsAspirersAspirersAspirers
5MonthJunSepAprJanJun
6Duration12232
7
8Execution2
9ExecutionPOSonshelfsignagePrintTelevisionCommercialDigitalRadio
10SegmentSupermarketGrassRootsElitesAspirersGrassRoots
11MonthOctOctJunJanJun
12Duration11132
13
14Execution3
15ExecutionCinemaTelevisionCommercialBuyOneGetOneFree10%OffCinema
16SegmentElitesAspirersConvenienceStoreSupermarketElites
17MonthSepSepFebJanJun
18Duration12111
19
20Execution4
21ExecutionStoreStaffPromotionSponsorshipAdvertisingCustomerMagazineThreePacksforthePriceofTwoPrint
22SegmentSupermarketAspirersSupermarketSupermarketGrassRoots
23MonthOctOctJunSepJun
24Duration21111
Sheet1


and this is how I want it to look:
test.xls
LMNOPQRS
1Segment:
212345
3AspirersExecutionTelevisionCommercialTelevisionCommercialTelevisionCommercialTelevisionCommercialTelevisionCommercial
4MonthJunSepAprJanJun
5Duration12232
6ExecutionSponsorshipDigitalOutOfHome
7MonthOctJanJun
8Duration131
9ExecutionDigital
10MonthOct
11Duration1
12GrassRootsExecutionRadioRadio
13MonthSepJun
14Duration22
15ExecutionPrintPrint
16MonthOctJun
17Duration11
Sheet1
 

Excel Facts

Repeat Last Command
Pressing F4 adds dollar signs when editing a formula. When not editing, F4 repeats last command.
Would a pivot table do?

Code:
Sub Test()
    Dim Sh As Worksheet
    Dim ShNew As Worksheet
    Dim c As Integer
    Dim r As Long
    Dim NextRow As Long
    Set Sh = Worksheets("Sheet1")
    Set ShNew = Worksheets.Add
    ShNew.Range("A1:E1").Value = Array("Team", "Execution", "Segment", "Month", "Duration")
    NextRow = 2
    With Sh
        For c = 5 To 9
            r = 3
            Do While .Cells(r, c).Value <> ""
                ShNew.Cells(NextRow, 1) = .Cells(1, c)
                ShNew.Cells(NextRow, 2) = .Cells(r, c)
                ShNew.Cells(NextRow, 3) = .Cells(r + 1, c)
                ShNew.Cells(NextRow, 4) = .Cells(r + 2, c)
                ShNew.Cells(NextRow, 5) = .Cells(r + 3, c)
                NextRow = NextRow + 1
                r = r + 6
            Loop
        Next c
    End With
    ActiveWorkbook.PivotCaches.Add(SourceType:=xlDatabase, SourceData:= _
        ShNew.Name & "!" & ShNew.Range("A1").CurrentRegion.Address).CreatePivotTable TableDestination:="", TableName:="PT1"
    With ActiveSheet
        .PivotTableWizard TableDestination:=.Cells(1, 1)
        With .PivotTables("PT1")
            .SmallGrid = False
            .AddFields RowFields:=Array("Segment", "Execution", "Month"), ColumnFields:="Team"
            .PivotFields("Duration").Orientation = xlDataField
            .PivotFields("Segment").Subtotals = Array(False, False, False, False, False, False, False, False, False, False, False, False)
            .PivotFields("Execution").Subtotals = Array(False, False, False, False, False, False, False, False, False, False, False, False)
            .PivotFields("Month").Subtotals = Array(False, False, False, False, False, False, False, False, False, False, False, False)
            .ColumnGrand = False
            .RowGrand = False
        End With
        .Cells.EntireColumn.AutoFit
    End With
End Sub
 
Upvote 0

Forum statistics

Threads
1,213,536
Messages
6,114,205
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