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 261 262 263 264 265 266 267 268 269 270 271 272 273 274 275 276 277 278 279 280 281 282 283 284 285 286 287 288 289 290 291 292 293 294 295 296 297 298 299 300 301 302 303 304 305 306 307 308 309 310 311 312 313 314 315 316 317 318 319 320 321 322 323 324 325 326 327 328 329 330 331 332 333 334 335 336 337 338 339 340 341 342 343 344 345 346 347 348 349 350 351 352 353 354 355 356 357 358 359 360 361 362 363 364 365 366 367 368 369 370 371 372 373 374 375 376 377 378 379 380 381 382 383 384 385 386 387 388 389 390 391 392 393 394 395 396 397 398 399 400 401 402 403 404 405 406 407 408 409 410 411 412 413 414 415 416 417 418 419 420 421 422 423 424 425 426 427 428 429 430 431 432 433 434 435 436 437 438 439 440 441 442 443 444 445 446 447 448 449 450 451 452 453 454 455 456 457 458 459 460 461 462 463 464 465 466 467 468 469 470 471 472 473 474 475 476 477 478 479 480 481 482 483 484 485 486 487 488 489 490 491 492 493 494 495 496 497 498 499 500 501 502 503 504 505 506 507 508 509 510 511 512 513 514 515 516 517 518 519 520 521 522 523 524 525 526 527 528 529 530 531 532 533 534 535 536 537 538 539 540 541 542 543 544 545 546 547 548 549 550 551 552 553 554 555 556 557 558 559 560 561 562 563 564 565 566 567 568 569 570 571 572 573 574 575 576 577 578 579 580 581 582 583 584 585 586 587 588 589 590 591 592 593 594 595 596 597 598 599 600 601 602 603 604 605 606 607 608 609 610 611 612 613 614 615 616 617 618 619 620 621 622 623 624 625 626 627 628 629 630 631 632 633 634 635 636 637 638 639 640 641 642 643 644 645 646 647 648 649 650 651 652 653 654 655 656 657 658 659 660 661 662 663 664 665 666 667 668 669 670 671 672 673 674 675 676 677 678 679 680 681 682 683 684 685 686 687 688 689 690 691 692 693 694 695 696 697 698 699 700 701 702 703 704 705 706 707 708 709 710 711 712 713 714 715 716 717 718 719 720 721 722 723 724 725 726 727 728 729 730 731 732 733 734 735 736 737 738 739 740 741 742 743 744 745 746 747 748 749 750 751 752 753 754 755 756 757 758 759 760 761 762 763 764 765 766 767 768 769 770 771 772 773 774 775 776 777 778 779 780 781 782 783 784 785 786 787 788 789 790 791 792 793 794 795 796 797 798 799 800 801 802 803 804 805 806 807 808
| Sub AjoutTCDSommaire()
numBouton = MsgBox("Voulez-vous actualiser les données avant?", vbQuestion + vbYesNo)
If numBouton = vbYes Then
Call BoutonActuaTableauS
End If
Application.ScreenUpdating = False
Dim Feuille As Worksheet
Dim PlageDonnees5 As Range
Dim PlageDonnees6 As Range
Dim PlageDonnees7 As Range
Dim PlageDonnees8 As Range
Dim PlageDonnees10 As Range
Dim PlageDestination5 As Range
Dim PlageDestination6 As Range
Dim PlageDestination7 As Range
Dim PlageDestination8 As Range
Dim PlageDestination10 As Range
Dim TCD5 As PivotTable
Dim TCD6 As PivotTable
Dim TCD7 As PivotTable
Dim TCD8 As PivotTable
Dim TCD10 As PivotTable
Dim FiltreProjet As String
Dim compteur As Integer
Dim AucunADC As Boolean
Set Feuille = Worksheets("Sommaire")
compteur = 0
If ProjetExiste(Range("NumProjet")) = False Then
MsgBox "Projet inexistant"
Exit Sub
End If
If PivotTableExists(Feuille, "TCD5") = True Then
SuppTCD Feuille, "TCD5"
End If
If PivotTableExists(Feuille, "TCD6") = True Then
SuppTCD Feuille, "TCD6"
End If
If PivotTableExists(Feuille, "TCD7") = True Then
SuppTCD Feuille, "TCD7"
End If
If PivotTableExists(Feuille, "TCD8") = True Then
SuppTCD Feuille, "TCD8"
End If
If PivotTableExists(Feuille, "TCD10") = True Then
SuppTCD Feuille, "TCD10"
End If
Feuille.Range("Y11:Z22").Clear
If Feuille.Cells.FormatConditions.Count > 0 Then
Feuille.Cells.FormatConditions.Delete 'supprime les MEF conditionnelles existantes
End If
' Définir les plages de données, les plages de destination et la plage de filtre
Set PlageDonnees5 = Range("TAB_contrat")
Set PlageDonnees6 = Range("TAB_avenants")
Set PlageDonnees7 = Range("TAB_listeADC")
Set PlageDonnees8 = Range("TAB_listeFact")
Set PlageDonnees10 = Range("TAB_listeADC")
Set PlageDestination5 = Feuille.Range("B11")
Set PlageDestination6 = Feuille.Range("G11")
Set PlageDestination7 = Feuille.Range("M11")
Set PlageDestination8 = Feuille.Range("R11")
Set PlageDestination10 = Feuille.Range("AB33")
FiltreProjet = Range("NumProjet")
AucunADC = False
' Créer et nommer les tableaux croisés dynamiques
ActiveWorkbook.PivotCaches.Create(SourceType:=xlDatabase, SourceData:=PlageDonnees5, Version:=8).CreatePivotTable _
TableDestination:=PlageDestination5, TableName:="TCD5", DefaultVersion:=8
ActiveWorkbook.PivotCaches.Create(SourceType:=xlDatabase, SourceData:=PlageDonnees6, Version:=8).CreatePivotTable _
TableDestination:=PlageDestination6, TableName:="TCD6", DefaultVersion:=8
ActiveWorkbook.PivotCaches.Create(SourceType:=xlDatabase, SourceData:=PlageDonnees7, Version:=8).CreatePivotTable _
TableDestination:=PlageDestination7, TableName:="TCD7", DefaultVersion:=8
ActiveWorkbook.PivotCaches.Create(SourceType:=xlDatabase, SourceData:=PlageDonnees8, Version:=8).CreatePivotTable _
TableDestination:=PlageDestination8, TableName:="TCD8", DefaultVersion:=8
ActiveWorkbook.PivotCaches.Create(SourceType:=xlDatabase, SourceData:=PlageDonnees10, Version:=8).CreatePivotTable _
TableDestination:=PlageDestination10, TableName:="TCD10", DefaultVersion:=8
Set TCD5 = Feuille.PivotTables("TCD5")
Set TCD6 = Feuille.PivotTables("TCD6")
Set TCD7 = Feuille.PivotTables("TCD7")
Set TCD8 = Feuille.PivotTables("TCD8")
Set TCD10 = Feuille.PivotTables("TCD10")
Tableau5:
' Création du TCD5
With TCD5
.ColumnGrand = True
.HasAutoFormat = True
.DisplayErrorString = True
.DisplayNullString = True
.EnableDrilldown = True
.ErrorString = ""
.MergeLabels = False
.NullString = ""
.PageFieldOrder = 2
.PageFieldWrapCount = 0
.PreserveFormatting = True
.RowGrand = False
.SaveData = True
.PrintTitles = False
.RepeatItemsOnEachPrintedPage = True
.TotalsAnnotation = False
.CompactRowIndent = 1
.InGridDropZones = False
.DisplayFieldCaptions = True
.DisplayMemberPropertyTooltips = False
.DisplayContextTooltips = True
.ShowDrillIndicators = False
.PrintDrillIndicators = False
.AllowMultipleFilters = False
.SortUsingCustomLists = True
.FieldListSortAscending = False
.ShowValuesRow = False
.CalculatedMembersInFilters = False
.RowAxisLayout xlCompactRow
.TableStyle2 = "PivotStyleLightGRHR"
End With
' Ajout 1er élément de ligne
With TCD5.PivotFields("Contract_Project_Code")
.Orientation = xlRowField
.Position = 1
.LayoutForm = xlTabular
.RepeatLabels = True
.Subtotals = Array(False, False, False, False, False, False, False, False, False, False, False, False)
.ClearAllFilters
.EnableMultiplePageItems = True
.DataRange.NumberFormat = " __@"
On Error GoTo fin5
For Each PvtItm In .PivotItems
If LCase(PvtItm.Name) Like FiltreProjet & "*" Then
PvtItm.Visible = True
compteur = compteur + 1
Else
PvtItm.Visible = False
End If
Next PvtItm
If compteur > 1 Then
.Subtotals = Array(True, False, False, False, False, False, False, False, False, False, False, False)
End If
On Error GoTo 0
End With
' Ajout des éléments de données
With TCD5
.AddDataField TCD5.PivotFields("ContractAmount"), "Montant Bordereau", xlSum
.PivotFields("Montant Bordereau").NumberFormat = "_ * # ### ##0.00_) $_ ;_ * (# ### ##0.00) $_ ;_ * ""-""??_) $_ ;_ @_ "
.CalculatedFields.Add "Avancement", "=BilledAmount/ContractAmount"
.AddDataField TCD5.PivotFields("Avancement"), "Progression", xlSum
.PivotFields("Progression").NumberFormat = "0.00%"
.AddDataField TCD5.PivotFields("BilledAmount"), "Montant facturé", xlSum
.PivotFields("Montant facturé").NumberFormat = "_ * # ### ##0.00_) $_ ;_ * (# ### ##0.00) $_ ;_ * ""-""??_) $_ ;_ @_ "
.CompactLayoutRowHeader = "Projet"
End With
Tableau6:
' Création du TCD6
compteur = 0
With TCD6
.ColumnGrand = True
.HasAutoFormat = True
.DisplayErrorString = True
.DisplayNullString = True
.EnableDrilldown = True
.ErrorString = ""
.MergeLabels = False
.NullString = ""
.PageFieldOrder = 2
.PageFieldWrapCount = 0
.PreserveFormatting = True
.RowGrand = False
.SaveData = True
.PrintTitles = False
.RepeatItemsOnEachPrintedPage = True
.TotalsAnnotation = False
.CompactRowIndent = 1
.InGridDropZones = False
.DisplayFieldCaptions = True
.DisplayMemberPropertyTooltips = False
.DisplayContextTooltips = True
.ShowDrillIndicators = False
.PrintDrillIndicators = False
.AllowMultipleFilters = False
.SortUsingCustomLists = True
.FieldListSortAscending = False
.ShowValuesRow = False
.CalculatedMembersInFilters = False
.RowAxisLayout xlCompactRow
.TableStyle2 = "PivotStyleLightGRHR"
End With
' Ajout 1er élément de ligne
With TCD6.PivotFields("Contract_Project_Code")
.Orientation = xlRowField
.Position = 1
.LayoutForm = xlTabular
.RepeatLabels = True
.Subtotals = Array(False, False, False, False, False, False, False, False, False, False, False, False)
.ClearAllFilters
.EnableMultiplePageItems = True
.DataRange.NumberFormat = " __@"
On Error GoTo fin6
For Each PvtItm In .PivotItems
If LCase(PvtItm.Name) Like FiltreProjet & "*" Then
PvtItm.Visible = True
compteur = compteur + 1
Else
PvtItm.Visible = False
End If
Next PvtItm
If compteur > 1 Then
.Subtotals = Array(True, False, False, False, False, False, False, False, False, False, False, False)
End If
On Error GoTo 0
End With
' Ajout des éléments de données
With TCD6
.AddDataField TCD6.PivotFields("RequestedAmount"), "Montant demandé", xlSum
.PivotFields("Montant demandé").NumberFormat = "_ * # ### ##0.00_) $_ ;_ * (# ### ##0.00) $_ ;_ * ""-""??_) $_ ;_ @_ "
.AddDataField TCD6.PivotFields("ApprovedAmount"), "Montant approuvé", xlSum
.PivotFields("Montant approuvé").NumberFormat = "_ * # ### ##0.00_) $_ ;_ * (# ### ##0.00) $_ ;_ * ""-""??_) $_ ;_ @_ "
.CalculatedFields.Add "Avancement", "=BilledAmount/ApprovedAmount"
.AddDataField TCD6.PivotFields("Avancement"), "Progression", xlSum
.PivotFields("Progression").NumberFormat = "0.00%"
.AddDataField TCD6.PivotFields("BilledAmount"), "Montant facturé", xlSum
.PivotFields("Montant facturé").NumberFormat = "_ * # ### ##0.00_) $_ ;_ * (# ### ##0.00) $_ ;_ * ""-""??_) $_ ;_ @_ "
.CompactLayoutRowHeader = "Projet"
End With
Tableau7:
' Création du TCD7
compteur = 0
With TCD7
.ColumnGrand = True
.HasAutoFormat = True
.DisplayErrorString = True
.DisplayNullString = True
.EnableDrilldown = True
.ErrorString = ""
.MergeLabels = False
.NullString = ""
.PageFieldOrder = 2
.PageFieldWrapCount = 0
.PreserveFormatting = True
.RowGrand = False
.SaveData = True
.PrintTitles = False
.RepeatItemsOnEachPrintedPage = True
.TotalsAnnotation = False
.CompactRowIndent = 1
.InGridDropZones = False
.DisplayFieldCaptions = True
.DisplayMemberPropertyTooltips = False
.DisplayContextTooltips = True
.ShowDrillIndicators = False
.PrintDrillIndicators = False
.AllowMultipleFilters = False
.SortUsingCustomLists = True
.FieldListSortAscending = False
.ShowValuesRow = False
.CalculatedMembersInFilters = False
.RowAxisLayout xlCompactRow
.TableStyle2 = "PivotStyleLightGRHR"
End With
' Ajout 1er élément de ligne
With TCD7.PivotFields("Project_Code")
.Orientation = xlRowField
.Position = 1
.LayoutForm = xlTabular
.RepeatLabels = True
.Subtotals = Array(False, False, False, False, False, False, False, False, False, False, False, False)
.ClearAllFilters
.EnableMultiplePageItems = True
.DataRange.NumberFormat = " __@"
On Error GoTo fin7
For Each PvtItm In .PivotItems
If LCase(PvtItm.Name) Like FiltreProjet & "*" Then
PvtItm.Visible = True
compteur = compteur + 1
Else
PvtItm.Visible = False
End If
Next PvtItm
If compteur > 1 Then
.Subtotals = Array(True, False, False, False, False, False, False, False, False, False, False, False)
End If
On Error GoTo 0
End With
' Ajout 2e élément de ligne
With TCD7.PivotFields("Statut DM")
.Orientation = xlRowField
.Position = 2
.LayoutForm = xlTabular
.RepeatLabels = True
.Subtotals = Array(False, False, False, False, False, False, False, False, False, False, False, False)
.Caption = "État"
End With
' Ajout des éléments de données
With TCD7
.AddDataField TCD7.PivotFields("TotalProposedAmount"), "Montant demandé", xlSum
.PivotFields("Montant demandé").NumberFormat = "_ * # ### ##0.00_) $_ ;_ * (# ### ##0.00) $_ ;_ * ""-""??_) $_ ;_ @_ "
.AddDataField TCD7.PivotFields("TotalAmountAccepted"), "Montant approuvé", xlSum
.PivotFields("Montant approuvé").NumberFormat = "_ * # ### ##0.00_) $_ ;_ * (# ### ##0.00) $_ ;_ * ""-""??_) $_ ;_ @_ "
.CompactLayoutRowHeader = "Projet"
End With
Tableau8:
' Création du TCD8
compteur = 0
With TCD8
.ColumnGrand = True
.HasAutoFormat = True
.DisplayErrorString = True
.DisplayNullString = True
.EnableDrilldown = True
.ErrorString = ""
.MergeLabels = False
.NullString = ""
.PageFieldOrder = 2
.PageFieldWrapCount = 0
.PreserveFormatting = True
.RowGrand = False
.SaveData = True
.PrintTitles = False
.RepeatItemsOnEachPrintedPage = True
.TotalsAnnotation = False
.CompactRowIndent = 1
.InGridDropZones = False
.DisplayFieldCaptions = True
.DisplayMemberPropertyTooltips = False
.DisplayContextTooltips = True
.ShowDrillIndicators = False
.PrintDrillIndicators = False
.AllowMultipleFilters = False
.SortUsingCustomLists = True
.FieldListSortAscending = False
.ShowValuesRow = False
.CalculatedMembersInFilters = False
.RowAxisLayout xlCompactRow
.TableStyle2 = "PivotStyleLightGRHR"
End With
' Ajout 1er élément de ligne
With TCD8.PivotFields("Project_Code")
.Orientation = xlRowField
.Position = 1
.LayoutForm = xlTabular
.RepeatLabels = True
.Subtotals = Array(False, False, False, False, False, False, False, False, False, False, False, False)
.ClearAllFilters
.EnableMultiplePageItems = True
.DataRange.NumberFormat = " __@"
On Error GoTo fin8
For Each PvtItm In .PivotItems
If LCase(PvtItm.Name) Like FiltreProjet & "*" Then
PvtItm.Visible = True
compteur = compteur + 1
Else
PvtItm.Visible = False
End If
Next PvtItm
If compteur > 1 Then
.Subtotals = Array(True, False, False, False, False, False, False, False, False, False, False, False)
End If
On Error GoTo 0
End With
' Ajout 2e élément de ligne
With TCD8.PivotFields("Code activité")
.Orientation = xlRowField
.Position = 2
.LayoutForm = xlTabular
.RepeatLabels = True
.Subtotals = Array(False, False, False, False, False, False, False, False, False, False, False, False)
.Caption = "Activité"
End With
' Ajout des éléments de données
With TCD8
.CalculatedFields.Add "Montant total sans retenu", "=TotalAmount-HoldbackAmount"
.AddDataField TCD8.PivotFields("Montant total sans retenu"), "Montant Tax In", xlSum
.PivotFields("Montant Tax In").NumberFormat = "_ * # ### ##0.00_) $_ ;_ * (# ### ##0.00) $_ ;_ * ""-""??_) $_ ;_ @_ "
.AddDataField TCD8.PivotFields("HoldbackAmount"), "Retenue", xlSum
.PivotFields("Retenue").NumberFormat = "_ * # ### ##0.00_) $_ ;_ * (# ### ##0.00) $_ ;_ * ""-""??_) $_ ;_ @_ "
.AddDataField TCD8.PivotFields("ReceiptAmount"), "Montant reçu", xlSum
.PivotFields("Montant reçu").NumberFormat = "_ * # ### ##0.00_) $_ ;_ * (# ### ##0.00) $_ ;_ * ""-""??_) $_ ;_ @_ "
.AddDataField TCD8.PivotFields("HoldbackReceiptAmount"), "Retenue reçue", xlSum
.PivotFields("Retenue reçue").NumberFormat = "_ * # ### ##0.00_) $_ ;_ * (# ### ##0.00) $_ ;_ * ""-""??_) $_ ;_ @_ "
.CompactLayoutRowHeader = "Projet"
End With
Tableau9:
' Création du tableau de dénonciation
With Feuille
.Range("Y11:Z11").Merge
.Range("Y22:Z22").Merge
.Range("Y11").HorizontalAlignment = xlCenter
.Range("Y11").Formula2 = "=IF(NOT(ISBLANK($Y$12)),""Projet ""&NumProjet,"""")"
.Range("Y12") = "Bord. contrat"
.Range("Z12").Formula2 = "=SUMIFS(ContractBreakdown[ContractAmount],ContractBreakdown[Contract_Project_Code],NumProjet)"
.Range("Z12").NumberFormat = "_ * # ### ### ##0.00_) $_ ;_ * (# ### ### ##0.00) $_ ;_ * ""-""??_) $_ ;_ @_ "
.Range("Y13") = "Bord. avenants"
.Range("Z13").Formula2 = "=SUMIFS(ContractChangeOrder[ApprovedAmount],ContractChangeOrder[Contract_Project_Code],NumProjet)"
.Range("Z13").NumberFormat = "_ * # ### ### ##0.00_) $_ ;_ * (# ### ### ##0.00) $_ ;_ * ""-""??_) $_ ;_ @_ "
.Range("Y14") = "DM entrées"
.Range("Z14").Formula2 = "=SUMIFS(ChangeOrder[ProposedAmount],ChangeOrder[Project_Code],NumProjet,ChangeOrder[Statut DM],""Entré"")"
.Range("Z14").NumberFormat = "_ * # ### ### ##0.00_) $_ ;_ * (# ### ### ##0.00) $_ ;_ * ""-""??_) $_ ;_ @_ "
.Range("Y15") = "DM soumises"
.Range("Z15").Formula2 = "=SUMIFS(ChangeOrder[ProposedAmount],ChangeOrder[Project_Code],NumProjet,ChangeOrder[Statut DM],""Soumis"")"
.Range("Z15").NumberFormat = "_ * # ### ### ##0.00_) $_ ;_ * (# ### ### ##0.00) $_ ;_ * ""-""??_) $_ ;_ @_ "
.Range("Y16") = "DM acceptées"
.Range("Z16").Formula2 = "=SUMIFS(ChangeOrder[AcceptedAmount],ChangeOrder[Project_Code],NumProjet,ChangeOrder[Statut DM],""Accepté"")"
.Range("Z16").NumberFormat = "_ * # ### ### ##0.00_) $_ ;_ * (# ### ### ##0.00) $_ ;_ * ""-""??_) $_ ;_ @_ "
.Range("Y17") = "Total"
.Range("Z17").Formula2 = "=SUM(Z12:Z16)"
.Range("Z17").NumberFormat = "_ * # ### ### ##0.00_) $_ ;_ * (# ### ### ##0.00) $_ ;_ * ""-""??_) $_ ;_ @_ "
.Range("Y18") = "Dénonciation"
.Range("Z18").Formula2 = "=IFERROR(IF(XLOOKUP(XLOOKUP(TEXT(NumProjet,""@""),Contract[Project_Code],Contract[AdditionalFieldsLink],,0),P2_YAFContract[CPT],P2_YAFContract[ID000039],,0)=0,XLOOKUP(XLOOKUP(TEXT(NumProjet,""@""),Contract[Project_Code],Contract[AdditionalFieldsLink],,0),P2_YAFContract[CPT],P2_YAFContract[ID000037],,0),XLOOKUP(XLOOKUP(TEXT(NumProjet,""@""),Contract[Project_Code],Contract[AdditionalFieldsLink],,0),P2_YAFContract[CPT],P2_YAFContract[ID000039],,0)),0)"
.Range("Z18").NumberFormat = "_ * # ### ### ##0.00_) $_ ;_ * (# ### ### ##0.00) $_ ;_ * ""-""??_) $_ ;_ @_ "
.Range("Y19") = "Différence"
.Range("Z19").Formula2 = "=Z18-Z17"
.Range("Z19").NumberFormat = "_ * # ### ### ##0.00_) $_ ;_ * (# ### ### ##0.00) $_ ;_ * ""-""??_) $_ ;_ @_ "
.Range("Y20") = "% dénoncé"
.Range("Z20").Formula2 = "=XLOOKUP(XLOOKUP(TEXT(NumProjet,""@""),Contract[Project_Code],Contract[AdditionalFieldsLink],,0),P2_YAFContract[CPT],P2_YAFContract[ID000121],,0)"
.Range("Y21") = "Suggérée"
.Range("Z21").Formula2 = "=IF(Z20="""",IF(Z17<1000000,Z17*1.1,MAX(1000000*1.1,Z17*1.05)),Z17*(Z20+1))"
.Range("Z21").NumberFormat = "_ * # ### ### ##0.00_) $_ ;_ * (# ### ### ##0.00) $_ ;_ * ""-""??_) $_ ;_ @_ "
.Range("Y12:Z21").Borders(xlInsideVertical).Color = 14277081
.Range("Y12:Z21").Borders(xlInsideHorizontal).Color = 14277081
End With
Tableau10:
' Création du TCD10
If AucunADC = True Then GoTo MEF
compteur = 0
With TCD10
.ColumnGrand = True
.HasAutoFormat = True
.DisplayErrorString = True
.DisplayNullString = True
.EnableDrilldown = True
.ErrorString = ""
.MergeLabels = False
.NullString = ""
.PageFieldOrder = 2
.PageFieldWrapCount = 0
.PreserveFormatting = True
.RowGrand = False
.SaveData = True
.PrintTitles = False
.RepeatItemsOnEachPrintedPage = True
.TotalsAnnotation = False
.CompactRowIndent = 1
.InGridDropZones = False
.DisplayFieldCaptions = True
.DisplayMemberPropertyTooltips = False
.DisplayContextTooltips = True
.ShowDrillIndicators = False
.PrintDrillIndicators = False
.AllowMultipleFilters = False
.SortUsingCustomLists = True
.FieldListSortAscending = False
.ShowValuesRow = False
.CalculatedMembersInFilters = False
.RowAxisLayout xlCompactRow
.TableStyle2 = "PivotStyleLightGRHR"
End With
' Ajout 1er élément de ligne
With TCD10.PivotFields("Project_Code")
.Orientation = xlRowField
.Position = 1
.LayoutForm = xlTabular
.RepeatLabels = True
.Subtotals = Array(False, False, False, False, False, False, False, False, False, False, False, False)
.ClearAllFilters
.EnableMultiplePageItems = True
.DataRange.NumberFormat = " __@"
On Error GoTo fin10
For Each PvtItm In .PivotItems
If LCase(PvtItm.Name) Like FiltreProjet & "*" Then
PvtItm.Visible = True
compteur = compteur + 1
Else
PvtItm.Visible = False
End If
Next PvtItm
If compteur > 1 Then
.Subtotals = Array(True, False, False, False, False, False, False, False, False, False, False, False)
End If
On Error GoTo 0
End With
' Ajout 2e élément de ligne
With TCD10.PivotFields("Suivi")
.Orientation = xlRowField
.Position = 2
.LayoutForm = xlTabular
.RepeatLabels = True
.Subtotals = Array(False, False, False, False, False, False, False, False, False, False, False, False)
.ClearAllFilters
.EnableMultiplePageItems = True
On Error GoTo fin10
.PivotItems("").Visible = False
On Error GoTo 0
End With
' Ajout 3e élément de ligne
With TCD10.PivotFields("Number")
.Orientation = xlRowField
.Position = 3
.LayoutForm = xlTabular
.RepeatLabels = True
.Subtotals = Array(False, False, False, False, False, False, False, False, False, False, False, False)
.Caption = "DM"
End With
' Ajout 4e élément de ligne
With TCD10.PivotFields("Description")
.Orientation = xlRowField
.Position = 4
.LayoutForm = xlTabular
.RepeatLabels = True
.Subtotals = Array(False, False, False, False, False, False, False, False, False, False, False, False)
End With
' Ajout 5e élément de ligne
With TCD10.PivotFields("SubmittedDate")
.Orientation = xlRowField
.Position = 5
.LayoutForm = xlTabular
.RepeatLabels = True
.Subtotals = Array(False, False, False, False, False, False, False, False, False, False, False, False)
.Caption = "Date soumise"
End With
TCD10.CompactLayoutRowHeader = "Projet"
MEF:
' Ajout des mises en forme conditionnelles
With Feuille
' MEF 1
.Range("$A$10").FormatConditions.Add Type:=xlExpression, Formula1:="=NON($B$10="""")"
' MEF 2
.Range("$A$11:$A$100").FormatConditions.Add Type:=xlExpression, Formula1:="=NON(ESTVIDE($B11))"
' MEF 3
.Range("$B$10").FormatConditions.Add Type:=xlExpression, Formula1:="=NON(ESTVIDE($B$11))"
' MEF 4
.Range("$F$10").FormatConditions.Add Type:=xlExpression, Formula1:="=OU(NON($B$10="""");NON($G$10=""""))"
' MEF 5
.Range("$F$11:$F$100").FormatConditions.Add Type:=xlExpression, Formula1:="=OU(NON(ESTVIDE($B11));NON(ESTVIDE($G11)))"
' MEF 6
.Range("$G$10").FormatConditions.Add Type:=xlExpression, Formula1:="=NON(ESTVIDE($G$11))"
' MEF 7
.Range("$L$10").FormatConditions.Add Type:=xlExpression, Formula1:="=OU(NON($G$10="""");NON($M$10=""""))"
' MEF 8
.Range("$L$11:$L$100").FormatConditions.Add Type:=xlExpression, Formula1:="=OU(NON(ESTVIDE($G11));NON(ESTVIDE($M11)))"
' MEF 9
.Range("$M$10").FormatConditions.Add Type:=xlExpression, Formula1:="=NON(ESTVIDE($M$11))"
' MEF 10
.Range("$Q$10").FormatConditions.Add Type:=xlExpression, Formula1:="=OU(NON($M$10="""");NON($R$10=""""))"
' MEF 11
.Range("$Q$11:$Q$100").FormatConditions.Add Type:=xlExpression, Formula1:="=OU(NON(ESTVIDE($M11));NON(ESTVIDE($R11)))"
' MEF 12
.Range("$R$10").FormatConditions.Add Type:=xlExpression, Formula1:="=NON(ESTVIDE($R$11))"
' MEF 13
.Range("$X$10").FormatConditions.Add Type:=xlExpression, Formula1:="=OU(NON($R$10="""");NON($Y$10=""""))"
' MEF 14
.Range("$X$11:$X$100").FormatConditions.Add Type:=xlExpression, Formula1:="=OU(NON(ESTVIDE($R11));NON(ESTVIDE($Y11));$Y10=""Suggérée"")"
' MEF 15
.Range("$Y$10").FormatConditions.Add Type:=xlExpression, Formula1:="=NON(ESTVIDE($Y$11))"
' MEF 16
.Range("$AA$10:$AA$30,$AG$10:$AG$30,$AB$10:$AF$10,$AB$20:$AF$20,$AB$30:$AF$30").FormatConditions.Add Type:=xlExpression, Formula1:="=NON($AB$11="""")"
' MEF 17
.Range("$AB$11,$AB$21").FormatConditions.Add Type:=xlExpression, Formula1:="=NON($AB$11="""")"
' MEF 18
.Range("$AB$12:$AF$19,$AB$22:$AF$29").FormatConditions.Add Type:=xlExpression, Formula1:="=NON($AB$11="""")"
' MEF 19
.Range("$AA$32,$AG$32").FormatConditions.Add Type:=xlExpression, Formula1:="=NON($AB$32="""")"
' MEF 20
.Range("$AB$32").FormatConditions.Add Type:=xlExpression, Formula1:="=NON($AB$33="""")"
' MEF 21
.Range("$AA$33:$AA$100,$AG$33:$AG$100").FormatConditions.Add Type:=xlExpression, Formula1:="=NON(ESTVIDE($AB33))"
' MEF 22
.Range("$A$12:$E$101").FormatConditions.Add Type:=xlExpression, Formula1:="=$B11=""Total général"""
' MEF 23
.Range("$F$12:$F$101").FormatConditions.Add Type:=xlExpression, Formula1:="=OU($B11=""Total général"";$G11=""Total général"")"
' MEF 24
.Range("$G$12:$K$101").FormatConditions.Add Type:=xlExpression, Formula1:="=$G11=""Total général"""
' MEF 25
.Range("$L$12:$L$101").FormatConditions.Add Type:=xlExpression, Formula1:="=OU($G11=""Total général"";$M11=""Total général"")"
' MEF 26
.Range("$M$12:$P$101").FormatConditions.Add Type:=xlExpression, Formula1:="=$M11=""Total général"""
' MEF 27
.Range("$Q$12:$Q$101").FormatConditions.Add Type:=xlExpression, Formula1:="=OU($M11=""Total général"";$R11=""Total général"")"
' MEF 28
.Range("$R$12:$W$101").FormatConditions.Add Type:=xlExpression, Formula1:="=$R11=""Total général"""
' MEF 29
.Range("$X$12:$X$101").FormatConditions.Add Type:=xlExpression, Formula1:="=OU($R11=""Total général"";$Y10=""Suggérée"")"
' MEF 30
.Range("$Y$11,$Y$22").FormatConditions.Add Type:=xlExpression, Formula1:="=NON($Y$10="""")"
' MEF 31
.Range("$Y$12:$AA$101").FormatConditions.Add Type:=xlExpression, Formula1:="=$Y10=""Suggérée"""
' MEF 32
.Range("$AA$34:$AG$101").FormatConditions.Add Type:=xlExpression, Formula1:="=$AB33=""Total général"""
' MEF 33
.Range("$Z$19").FormatConditions.Add Type:=xlExpression, Formula1:="=$Z$19<0"
End With
' Ajout du format de toutes les MEF
With Feuille.Cells
.FormatConditions(1).Font.ThemeColor = xlThemeColorDark1
.FormatConditions(1).Interior.Color = 7828224
.FormatConditions(1).StopIfTrue = False
.FormatConditions(2).Font.ThemeColor = xlThemeColorDark1
.FormatConditions(2).Interior.Color = 7828224
.FormatConditions(2).StopIfTrue = False
.FormatConditions(3).Font.ThemeColor = xlThemeColorDark1
.FormatConditions(3).Font.Bold = True
.FormatConditions(3).Interior.Color = 7828224
.FormatConditions(3).StopIfTrue = False
.FormatConditions(4).Font.ThemeColor = xlThemeColorDark1
.FormatConditions(4).Interior.Color = 7828224
.FormatConditions(4).StopIfTrue = False
.FormatConditions(5).Font.ThemeColor = xlThemeColorDark1
.FormatConditions(5).Interior.Color = 7828224
.FormatConditions(5).StopIfTrue = False
.FormatConditions(6).Font.ThemeColor = xlThemeColorDark1
.FormatConditions(6).Font.Bold = True
.FormatConditions(6).Interior.Color = 7828224
.FormatConditions(6).StopIfTrue = False
.FormatConditions(7).Font.ThemeColor = xlThemeColorDark1
.FormatConditions(7).Interior.Color = 7828224
.FormatConditions(7).StopIfTrue = False
.FormatConditions(8).Font.ThemeColor = xlThemeColorDark1
.FormatConditions(8).Interior.Color = 7828224
.FormatConditions(8).StopIfTrue = False
.FormatConditions(9).Font.ThemeColor = xlThemeColorDark1
.FormatConditions(9).Font.Bold = True
.FormatConditions(9).Interior.Color = 7828224
.FormatConditions(9).StopIfTrue = False
.FormatConditions(10).Font.ThemeColor = xlThemeColorDark1
.FormatConditions(10).Interior.Color = 7828224
.FormatConditions(10).StopIfTrue = False
.FormatConditions(11).Font.ThemeColor = xlThemeColorDark1
.FormatConditions(11).Interior.Color = 7828224
.FormatConditions(11).StopIfTrue = False
.FormatConditions(12).Font.ThemeColor = xlThemeColorDark1
.FormatConditions(12).Font.Bold = True
.FormatConditions(12).Interior.Color = 7828224
.FormatConditions(12).StopIfTrue = False
.FormatConditions(13).Font.ThemeColor = xlThemeColorDark1
.FormatConditions(13).Interior.Color = 7828224
.FormatConditions(13).StopIfTrue = False
.FormatConditions(14).Font.ThemeColor = xlThemeColorDark1
.FormatConditions(14).Interior.Color = 7828224
.FormatConditions(14).StopIfTrue = False
.FormatConditions(15).Font.ThemeColor = xlThemeColorDark1
.FormatConditions(15).Font.Bold = True
.FormatConditions(15).Interior.Color = 7828224
.FormatConditions(15).StopIfTrue = False
.FormatConditions(16).Font.ThemeColor = xlThemeColorDark1
.FormatConditions(16).Interior.Color = 7828224
.FormatConditions(16).StopIfTrue = False
.FormatConditions(17).Font.ThemeColor = xlThemeColorDark1
.FormatConditions(17).Font.Bold = True
.FormatConditions(17).Interior.Color = 10918912
.FormatConditions(17).Borders.LineStyle = xlContinuous
.FormatConditions(17).Borders.Color = 7828224
.FormatConditions(17).StopIfTrue = False
.FormatConditions(18).Borders(xlBottom).Color = vbBlack
.FormatConditions(19).Font.ThemeColor = xlThemeColorDark1
.FormatConditions(19).Font.Bold = True
.FormatConditions(19).Interior.Color = 7828224
.FormatConditions(19).StopIfTrue = False
.FormatConditions(20).Font.ThemeColor = xlThemeColorDark1
.FormatConditions(20).Font.Bold = True
.FormatConditions(20).Interior.Color = 7828224
.FormatConditions(20).StopIfTrue = False
.FormatConditions(21).Font.ThemeColor = xlThemeColorDark1
.FormatConditions(21).Interior.Color = 7828224
.FormatConditions(21).StopIfTrue = False
.FormatConditions(22).Font.ThemeColor = xlThemeColorDark1
.FormatConditions(22).Font.Bold = True
.FormatConditions(22).Interior.Color = 7828224
.FormatConditions(22).StopIfTrue = False
.FormatConditions(23).Font.ThemeColor = xlThemeColorDark1
.FormatConditions(23).Font.Bold = True
.FormatConditions(23).Interior.Color = 7828224
.FormatConditions(23).StopIfTrue = False
.FormatConditions(24).Font.ThemeColor = xlThemeColorDark1
.FormatConditions(24).Font.Bold = True
.FormatConditions(24).Interior.Color = 7828224
.FormatConditions(24).StopIfTrue = False
.FormatConditions(25).Font.ThemeColor = xlThemeColorDark1
.FormatConditions(25).Font.Bold = True
.FormatConditions(25).Interior.Color = 7828224
.FormatConditions(25).StopIfTrue = False
.FormatConditions(26).Font.ThemeColor = xlThemeColorDark1
.FormatConditions(26).Font.Bold = True
.FormatConditions(26).Interior.Color = 7828224
.FormatConditions(26).StopIfTrue = False
.FormatConditions(27).Font.ThemeColor = xlThemeColorDark1
.FormatConditions(27).Font.Bold = True
.FormatConditions(27).Interior.Color = 7828224
.FormatConditions(27).StopIfTrue = False
.FormatConditions(28).Font.ThemeColor = xlThemeColorDark1
.FormatConditions(28).Font.Bold = True
.FormatConditions(28).Interior.Color = 7828224
.FormatConditions(28).StopIfTrue = False
.FormatConditions(29).Font.ThemeColor = xlThemeColorDark1
.FormatConditions(29).Font.Bold = True
.FormatConditions(29).Interior.Color = 7828224
.FormatConditions(29).StopIfTrue = False
.FormatConditions(30).Font.ThemeColor = xlThemeColorDark1
.FormatConditions(30).Font.Bold = True
.FormatConditions(30).Interior.Color = 10918912
.FormatConditions(30).Borders.LineStyle = xlContinuous
.FormatConditions(30).Borders.Color = 7828224
.FormatConditions(30).StopIfTrue = False
.FormatConditions(31).Font.ThemeColor = xlThemeColorDark1
.FormatConditions(31).Font.Bold = True
.FormatConditions(31).Interior.Color = 7828224
.FormatConditions(31).StopIfTrue = False
.FormatConditions(32).Font.ThemeColor = xlThemeColorDark1
.FormatConditions(32).Font.Bold = True
.FormatConditions(32).Interior.Color = 7828224
.FormatConditions(32).StopIfTrue = False
.FormatConditions(33).Font.Color = vbRed
.FormatConditions(33).Font.Bold = True
End With
Feuille.Range("B11").Select
ThisWorkbook.ShowPivotTableFieldList = False
Application.ScreenUpdating = True
Exit Sub
fin5:
Err.Clear
MsgBox "Le Bordereau (Contrat original) du projet " & FiltreProjet & " n'a pas été créé"
SuppTCD Feuille, "TCD5"
GoTo Tableau6
fin6:
Err.Clear
MsgBox "Le Bordereau (Avenants) du projet " & FiltreProjet & " n'a pas été créé"
SuppTCD Feuille, "TCD6"
GoTo Tableau7
fin7:
Err.Clear
MsgBox "Il n'y a pas d'avis de changement pour le projet " & FiltreProjet
SuppTCD Feuille, "TCD7"
AucunADC = True
GoTo Tableau8
fin8:
Err.Clear
MsgBox "Il n'y a pas de facturation pour le projet " & FiltreProjet
SuppTCD Feuille, "TCD8"
GoTo Tableau9
fin10:
Err.Clear
MsgBox "Il n'y a pas d'avis de changement à suivre pour le projet " & FiltreProjet
SuppTCD Feuille, "TCD10"
GoTo MEF
End Sub |
Partager