1 2 3 4 5 6 7 8 9 10 11 12 13 14 15 16 17 18 19 20 21 22 23 24 25 26 27 28 29 30 31 32 33 34 35 36 37 38 39 40 41 42 43 44 45 46 47 48 49 50 51 52 53 54 55 56 57 58 59 60 61 62 63 64 65 66 67 68 69 70 71 72 73 74 75 76 77 78 79 80 81 82 83 84 85 86 87 88 89 90 91 92 93 94 95 96 97 98 99 100 101 102 103 104 105 106 107 108 109 110 111 112 113 114 115 116 117 118 119 120 121 122 123 124 125 126 127 128 129 130 131 132 133 134 135 136 137 138 139 140 141 142 143 144 145 146 147 148 149 150 151 152 153 154 155 156 157 158 159 160 161 162 163 164 165 166 167 168 169 170 171 172 173 174 175 176 177 178 179 180 181 182 183 184 185 186 187 188 189 190 191 192 193 194 195 196 197 198 199 200 201 202 203 204 205 206 207 208 209 210 211 212 213 214 215 216 217 218 219 220 221 222 223 224 225 226 227 228 229 230 231 232 233 234 235 236 237 238 239 240 241 242 243 244 245 246 247 248 249 250 251 252 253 254 255 256 257 258 259 260
| Sub KPI()
Application.ScreenUpdating = False
' First Pivot Table
Dim objSheetWithData As Worksheet
Dim objSheetWithPivot As Worksheet
Dim objListObjectWithData As ListObject
Dim objConnection As WorkbookConnection
Dim objPivotCache As PivotCache
Dim objPivotTable As PivotTable
Dim objCubeField As CubeField
Dim objPivotField As PivotField
Set objSheetWithData = ActiveWorkbook.Sheets("LIVRAISON")
Set objSheetWithPivot = ActiveWorkbook.Sheets("TCD SERVICE LEVEL")
If objSheetWithData.ListObjects.Count > 0 Then
Set objListObjectWithData = objSheetWithData.ListObjects(1)
Else
Set objListObjectWithData = objSheetWithData.ListObjects.Add( _
SourceType:=xlSrcRange, _
Source:=objSheetWithData.Range("LIVRAISON"), _
XlListObjectHasHeaders:=xlYes)
End If
For Each objConnection In ActiveWorkbook.Connections
If objConnection.Type = xlConnectionTypeWORKSHEET Then objConnection.Delete
Next objConnection
Set objConnection = ActiveWorkbook.Connections.Add2( _
Name:="My Connection", _
Description:="My Connection Description", _
ConnectionString:="WORKSHEET;" & ActiveWorkbook.Name, _
CommandText:=objListObjectWithData.Parent.Name & "!" & objListObjectWithData.Name, _
lCmdtype:=XlCmdType.xlCmdExcel, _
CreateModelConnection:=True, _
ImportRelationships:=False)
Set objPivotCache = ActiveWorkbook.PivotCaches.Create( _
SourceType:=xlExternal, _
SourceData:=objConnection)
With objPivotCache
.RefreshOnFileOpen = False
.MissingItemsLimit = xlMissingItemsNone
End With
For Each objPivotTable In objSheetWithPivot.PivotTables
objPivotTable.TableRange2.Clear
Next objPivotTable
Set objPivotTable = objPivotCache.CreatePivotTable( _
TableDestination:=objSheetWithPivot.Range("A1"), TableName:="TCD LIVRAISON")
With objPivotTable.CubeFields(7)
.Orientation = xlPageField
.Caption = "IDH + Designation"
End With
objPivotTable.PageFields(1).Caption = "IDH + Designation"
With objPivotTable.CubeFields(9)
.Orientation = xlPageField
.Caption = "Brand"
End With
objPivotTable.PageFields(2).Caption = "Brand"
With objPivotTable.CubeFields(11)
.Orientation = xlPageField
.Caption = "Market"
End With
objPivotTable.PageFields(3).Caption = "Market"
With objPivotTable.CubeFields(8)
.Orientation = xlPageField
.Caption = "Type of Product"
End With
objPivotTable.PageFields(4).Caption = "Type of Product"
With objPivotTable.CubeFields(10)
.Orientation = xlPageField
.Caption = "Business Unit"
End With
objPivotTable.PageFields(5).Caption = "Business Unit"
With objPivotTable.CubeFields(15)
.Orientation = xlPageField
.Caption = "100% ?"
End With
objPivotTable.PageFields(6).Caption = "100% ?"
Set objCubeField = objPivotTable.CubeFields.GetMeasure( _
AttributeHierarchy:=objPivotTable.CubeFields(14), _
Function:=xlAverage, _
Caption:="Service Rate")
objPivotTable.AddDataField objCubeField
objPivotTable.DataFields(1).Caption = "Service Level (%)"
objPivotTable.DataFields(1).NumberFormat = "0.00%"
Set objCubeField = objPivotTable.CubeFields.GetMeasure( _
AttributeHierarchy:=objPivotTable.CubeFields(13), _
Function:=xlSum, _
Caption:="Quantity delivered")
objPivotTable.AddDataField objCubeField
objPivotTable.DataFields(2).Caption = "Quantity Delivered (PAL)"
objPivotTable.DataFields(2).NumberFormat = "#,##0.00"
Set objCubeField = objPivotTable.CubeFields.GetMeasure( _
AttributeHierarchy:=objPivotTable.CubeFields(7), _
Function:=xlDistinctCount, _
Caption:="IDH + Designation")
objPivotTable.AddDataField objCubeField
objPivotTable.DataFields(3).Caption = "Number of SKUs"
objPivotTable.DataFields(3).NumberFormat = "#,##0"
' Second Pivot Table
Set objSheetWithData = ActiveWorkbook.Sheets("NDR")
Set objSheetWithPivot = ActiveWorkbook.Sheets("TCD RUPTURE RATE")
If objSheetWithData.ListObjects.Count > 0 Then
Set objListObjectWithData = objSheetWithData.ListObjects(1)
Else
Set objListObjectWithData = objSheetWithData.ListObjects.Add( _
SourceType:=xlSrcRange, _
Source:=objSheetWithData.Range("NDR"), _
XlListObjectHasHeaders:=xlYes)
End If
For Each objConnection In ActiveWorkbook.Connections
If objConnection.Type = xlConnectionTypeWORKSHEET Then objConnection.Delete
Next objConnection
Set objConnection = ActiveWorkbook.Connections.Add2( _
Name:="My Connection", _
Description:="My Connection Description", _
ConnectionString:="WORKSHEET;" & ActiveWorkbook.Name, _
CommandText:=objListObjectWithData.Parent.Name & "!" & objListObjectWithData.Name, _
lCmdtype:=XlCmdType.xlCmdExcel, _
CreateModelConnection:=True, _
ImportRelationships:=False)
Set objPivotCache = ActiveWorkbook.PivotCaches.Create( _
SourceType:=xlExternal, _
SourceData:=objConnection)
With objPivotCache
.RefreshOnFileOpen = False
.MissingItemsLimit = xlMissingItemsNone
End With
For Each objPivotTable In objSheetWithPivot.PivotTables
objPivotTable.TableRange2.Clear
Next objPivotTable
Set objPivotTable = objPivotCache.CreatePivotTable( _
TableDestination:=objSheetWithPivot.Range("A1"), TableName:="TCD NDR")
With objPivotTable.CubeFields(6)
.Orientation = xlPageField
.Caption = "IDH + Designation"
End With
objPivotTable.PageFields(1).Caption = "IDH + Designation"
With objPivotTable.CubeFields(8)
.Orientation = xlPageField
.Caption = "Brand"
End With
objPivotTable.PageFields(2).Caption = "Brand"
With objPivotTable.CubeFields(10)
.Orientation = xlPageField
.Caption = "Market"
End With
objPivotTable.PageFields(3).Caption = "Market"
With objPivotTable.CubeFields(7)
.Orientation = xlPageField
.Caption = "Type of Product"
End With
objPivotTable.PageFields(4).Caption = "Type of Product"
With objPivotTable.CubeFields(9)
.Orientation = xlPageField
.Caption = "Business Unit"
End With
objPivotTable.PageFields(5).Caption = "Business Unit"
Set objCubeField = objPivotTable.CubeFields.GetMeasure( _
AttributeHierarchy:=objPivotTable.CubeFields(5), _
Function:=xlSum, _
Caption:="CPV (OOS) [EUR]")
objPivotTable.AddDataField objCubeField
objPivotTable.DataFields(1).Caption = "OOS (EUR)"
objPivotTable.DataFields(1).NumberFormat = "#,##0.00 "
Set objCubeField = objPivotTable.CubeFields.GetMeasure( _
AttributeHierarchy:=objPivotTable.CubeFields(4), _
Function:=xlSum, _
Caption:="(OOS) [CON]")
objPivotTable.AddDataField objCubeField
objPivotTable.DataFields(2).Caption = "OOS (CON)"
objPivotTable.DataFields(2).NumberFormat = "#,##0"
Set objCubeField = objPivotTable.CubeFields.GetMeasure( _
AttributeHierarchy:=objPivotTable.CubeFields(6), _
Function:=xlDistinctCount, _
Caption:="IDH + Designation")
objPivotTable.AddDataField objCubeField
objPivotTable.DataFields(3).Caption = "Number of SKUs"
objPivotTable.DataFields(3).NumberFormat = "#,##0"
' Third Pivot Table
Set objSheetWithData = ActiveWorkbook.Sheets("PRODUCTION")
Set objSheetWithPivot = ActiveWorkbook.Sheets("TCD VALUE AND VOLUME")
If objSheetWithData.ListObjects.Count > 0 Then
Set objListObjectWithData = objSheetWithData.ListObjects(1)
Else
Set objListObjectWithData = objSheetWithData.ListObjects.Add( _
SourceType:=xlSrcRange, _
Source:=objSheetWithData.Range("PRODUCTION"), _
XlListObjectHasHeaders:=xlYes)
End If
For Each objConnection In ActiveWorkbook.Connections
If objConnection.Type = xlConnectionTypeWORKSHEET Then objConnection.Delete
Next objConnection
Set objConnection = ActiveWorkbook.Connections.Add2( _
Name:="My Connection", _
Description:="My Connection Description", _
ConnectionString:="WORKSHEET;" & ActiveWorkbook.Name, _
CommandText:=objListObjectWithData.Parent.Name & "!" & objListObjectWithData.Name, _
lCmdtype:=XlCmdType.xlCmdExcel, _
CreateModelConnection:=True, _
ImportRelationships:=False)
Set objPivotCache = ActiveWorkbook.PivotCaches.Create( _
SourceType:=xlExternal, _
SourceData:=objConnection)
With objPivotCache
.RefreshOnFileOpen = False
.MissingItemsLimit = xlMissingItemsNone
End With
For Each objPivotTable In objSheetWithPivot.PivotTables
objPivotTable.TableRange2.Clear
Next objPivotTable
Set objPivotTable = objPivotCache.CreatePivotTable( _
TableDestination:=objSheetWithPivot.Range("A1"), TableName:="TCD PRODUCTION")
With objPivotTable.CubeFields(9)
.Orientation = xlPageField
.Caption = "IDH + Designation"
End With
objPivotTable.PageFields(1).Caption = "IDH + Designation"
With objPivotTable.CubeFields(11)
.Orientation = xlPageField
.Caption = "Brand"
End With
objPivotTable.PageFields(2).Caption = "Brand"
With objPivotTable.CubeFields(13)
.Orientation = xlPageField
.Caption = "Market"
End With
objPivotTable.PageFields(3).Caption = "Market"
With objPivotTable.CubeFields(10)
.Orientation = xlPageField
.Caption = "Type of Product"
End With
objPivotTable.PageFields(4).Caption = "Type of Product"
With objPivotTable.CubeFields(12)
.Orientation = xlPageField
.Caption = "Business Unit"
End With
objPivotTable.PageFields(5).Caption = "Business Unit"
Set objCubeField = objPivotTable.CubeFields.GetMeasure( _
AttributeHierarchy:=objPivotTable.CubeFields(5), _
Function:=xlSum, _
Caption:="Stock Value")
objPivotTable.AddDataField objCubeField
objPivotTable.DataFields(1).Caption = "Stock Value (EUR)"
objPivotTable.DataFields(1).NumberFormat = "#,##0.00 "
Set objCubeField = objPivotTable.CubeFields.GetMeasure( _
AttributeHierarchy:=objPivotTable.CubeFields(15), _
Function:=xlSum, _
Caption:="Amount of PAL")
objPivotTable.AddDataField objCubeField
objPivotTable.DataFields(2).Caption = "Quantity Produced (PAL)"
objPivotTable.DataFields(2).NumberFormat = "#,##0.00"
Set objCubeField = objPivotTable.CubeFields.GetMeasure( _
AttributeHierarchy:=objPivotTable.CubeFields(9), _
Function:=xlDistinctCount, _
Caption:="IDH + Designation")
objPivotTable.AddDataField objCubeField
objPivotTable.DataFields(3).Caption = "Number of SKUs"
objPivotTable.DataFields(3).NumberFormat = "#,##0"
Application.ScreenUpdating = True
End Sub |