349 lines
5.6 KiB
Markdown
349 lines
5.6 KiB
Markdown
# Freelance Dashboard - Formules et KPIs
|
|
|
|
## Vue d'ensemble
|
|
|
|
Toutes les formules utilisees dans le dashboard pour calculer les KPIs.
|
|
|
|
---
|
|
|
|
## 1. KPIs Principaux
|
|
|
|
### CA Total (periode selectionnee)
|
|
|
|
```excel
|
|
=SUMIFS(
|
|
Data_Revenus[Montant],
|
|
Data_Revenus[Date], ">=" & DateDebut,
|
|
Data_Revenus[Date], "<=" & DateFin
|
|
)
|
|
```
|
|
|
|
**Avec slicer client:**
|
|
```excel
|
|
=SUMIFS(
|
|
Data_Revenus[Montant],
|
|
Data_Revenus[Date], ">=" & DateDebut,
|
|
Data_Revenus[Date], "<=" & DateFin,
|
|
Data_Revenus[ClientID], ClientFiltre
|
|
)
|
|
```
|
|
|
|
---
|
|
|
|
### CA Mois en Cours
|
|
|
|
```excel
|
|
=SUMIFS(
|
|
Data_Revenus[Montant],
|
|
Data_Revenus[Date], ">=" & EOMONTH(TODAY(), -1) + 1,
|
|
Data_Revenus[Date], "<=" & EOMONTH(TODAY(), 0)
|
|
)
|
|
```
|
|
|
|
**Version simplifiee:**
|
|
```excel
|
|
=SUMPRODUCT(
|
|
(MONTH(Data_Revenus[Date]) = MONTH(TODAY())) *
|
|
(YEAR(Data_Revenus[Date]) = YEAR(TODAY())) *
|
|
Data_Revenus[Montant]
|
|
)
|
|
```
|
|
|
|
---
|
|
|
|
### Heures Totales (periode)
|
|
|
|
```excel
|
|
=SUMIFS(
|
|
Data_Temps[Heures],
|
|
Data_Temps[Date], ">=" & DateDebut,
|
|
Data_Temps[Date], "<=" & DateFin
|
|
)
|
|
```
|
|
|
|
---
|
|
|
|
### Taux Horaire Moyen
|
|
|
|
```excel
|
|
=IFERROR(
|
|
SUMIFS(Data_Revenus[Montant], ...) / SUMIFS(Data_Temps[Heures], ...),
|
|
0
|
|
)
|
|
```
|
|
|
|
**Format:** `# ##0.00 "€/h"`
|
|
|
|
---
|
|
|
|
### Nombre Clients Actifs
|
|
|
|
```excel
|
|
=SUMPRODUCT(
|
|
(COUNTIFS(
|
|
Data_Temps[ClientID], Data_Clients[ClientID],
|
|
Data_Temps[Date], ">=" & DateDebut,
|
|
Data_Temps[Date], "<=" & DateFin
|
|
) > 0) * 1
|
|
)
|
|
```
|
|
|
|
**Alternative avec UNIQUE (Excel 365):**
|
|
```excel
|
|
=COUNTA(UNIQUE(
|
|
FILTER(
|
|
Data_Temps[ClientID],
|
|
(Data_Temps[Date] >= DateDebut) * (Data_Temps[Date] <= DateFin)
|
|
)
|
|
))
|
|
```
|
|
|
|
---
|
|
|
|
### Top Client (par CA)
|
|
|
|
```excel
|
|
=INDEX(
|
|
Data_Clients[Nom],
|
|
MATCH(
|
|
MAX(
|
|
SUMIFS(
|
|
Data_Revenus[Montant],
|
|
Data_Revenus[ClientID], Data_Clients[ClientID]
|
|
)
|
|
),
|
|
SUMIFS(
|
|
Data_Revenus[Montant],
|
|
Data_Revenus[ClientID], Data_Clients[ClientID]
|
|
),
|
|
0
|
|
)
|
|
)
|
|
```
|
|
|
|
**Avec XLOOKUP (Excel 365):**
|
|
```excel
|
|
=LET(
|
|
clients, Data_Clients[ClientID],
|
|
noms, Data_Clients[Nom],
|
|
ca, SUMIFS(Data_Revenus[Montant], Data_Revenus[ClientID], clients),
|
|
maxCA, MAX(ca),
|
|
topClient, XLOOKUP(maxCA, ca, noms, "N/A"),
|
|
topClient
|
|
)
|
|
```
|
|
|
|
---
|
|
|
|
### Heures Cette Semaine
|
|
|
|
```excel
|
|
=SUMIFS(
|
|
Data_Temps[Heures],
|
|
Data_Temps[Date], ">=" & TODAY() - WEEKDAY(TODAY(), 2) + 1,
|
|
Data_Temps[Date], "<=" & TODAY() - WEEKDAY(TODAY(), 2) + 7
|
|
)
|
|
```
|
|
|
|
---
|
|
|
|
## 2. Formules pour Graphiques
|
|
|
|
### CA par Mois (12 derniers mois)
|
|
|
|
**Tableau helper:**
|
|
|
|
| Mois | CA |
|
|
|------|-----|
|
|
| =EOMONTH(TODAY(),-11) | =SUMPRODUCT((MONTH(Data_Revenus[Date])=MONTH(A2))*(YEAR(Data_Revenus[Date])=YEAR(A2))*Data_Revenus[Montant]) |
|
|
| ... | ... |
|
|
|
|
**Avec SEQUENCE (Excel 365):**
|
|
```excel
|
|
=LET(
|
|
mois, SEQUENCE(12, 1, EOMONTH(TODAY(), -11) + 1, 30),
|
|
ca, SUMPRODUCT(
|
|
(MONTH(Data_Revenus[Date]) = MONTH(mois)) *
|
|
(YEAR(Data_Revenus[Date]) = YEAR(mois)) *
|
|
Data_Revenus[Montant]
|
|
),
|
|
HSTACK(TEXT(mois, "mmm yy"), ca)
|
|
)
|
|
```
|
|
|
|
---
|
|
|
|
### Repartition CA par Client
|
|
|
|
```excel
|
|
=SUMIFS(
|
|
Data_Revenus[Montant],
|
|
Data_Revenus[ClientID], Data_Clients[@ClientID]
|
|
)
|
|
```
|
|
|
|
**Pourcentage:**
|
|
```excel
|
|
=[@CA] / SUM([CA])
|
|
```
|
|
|
|
---
|
|
|
|
### Heures par Semaine (8 dernieres semaines)
|
|
|
|
```excel
|
|
=SUMIFS(
|
|
Data_Temps[Heures],
|
|
Data_Temps[Date], ">=" & DebutSemaine,
|
|
Data_Temps[Date], "<=" & FinSemaine
|
|
)
|
|
```
|
|
|
|
---
|
|
|
|
## 3. Formules de Mise en Forme Conditionnelle
|
|
|
|
### KPI CA - Vert si objectif atteint
|
|
|
|
**Condition:** `=B2 >= Config!$C$5`
|
|
|
|
- Vert (#27AE60) si >= objectif
|
|
- Orange (#F39C12) si >= 80% objectif
|
|
- Rouge (#E74C3C) si < 80%
|
|
|
|
---
|
|
|
|
### Heures - Barre de progression
|
|
|
|
**Formule:** `=[@Heures] / 8` (sur une journee de 8h)
|
|
|
|
---
|
|
|
|
### Evolution - Fleche haut/bas
|
|
|
|
```excel
|
|
=IF([@CA] > [@CA_Precedent], "↑", IF([@CA] < [@CA_Precedent], "↓", "→"))
|
|
```
|
|
|
|
---
|
|
|
|
## 4. Formules Utilitaires
|
|
|
|
### Premier jour du mois
|
|
|
|
```excel
|
|
=EOMONTH(TODAY(), -1) + 1
|
|
```
|
|
|
|
### Dernier jour du mois
|
|
|
|
```excel
|
|
=EOMONTH(TODAY(), 0)
|
|
```
|
|
|
|
### Premier jour de la semaine (lundi)
|
|
|
|
```excel
|
|
=TODAY() - WEEKDAY(TODAY(), 2) + 1
|
|
```
|
|
|
|
### Numero de semaine
|
|
|
|
```excel
|
|
=WEEKNUM([@Date], 2)
|
|
```
|
|
|
|
### Nom du mois en francais
|
|
|
|
```excel
|
|
=TEXT([@Date], "mmmm")
|
|
```
|
|
|
|
---
|
|
|
|
## 5. Tableau Croise Dynamique - Champs Calcules
|
|
|
|
### Taux Horaire
|
|
|
|
```
|
|
= Montant / Heures
|
|
```
|
|
|
|
### CA Journalier Moyen
|
|
|
|
```
|
|
= Montant / COUNTA(Date)
|
|
```
|
|
|
|
### Heures par Jour Ouvre
|
|
|
|
```
|
|
= Heures / NETWORKDAYS(MIN(Date), MAX(Date))
|
|
```
|
|
|
|
---
|
|
|
|
## 6. Validation des Donnees
|
|
|
|
### Liste deroulante ClientID
|
|
|
|
```
|
|
Source: =INDIRECT("Data_Clients[ClientID]")
|
|
```
|
|
|
|
### Liste deroulante Type
|
|
|
|
```
|
|
Source: Facture,Acompte,Avoir,Autre
|
|
```
|
|
|
|
### Heures (entre 0.25 et 24)
|
|
|
|
```
|
|
Validation: Decimal
|
|
Minimum: 0.25
|
|
Maximum: 24
|
|
Message: "Entrez un nombre d'heures entre 0.25 et 24"
|
|
```
|
|
|
|
---
|
|
|
|
## 7. Exemples de Cellules Dashboard
|
|
|
|
### Cellule KPI - CA Total
|
|
|
|
```
|
|
Cellule: D4
|
|
Formule: =SUMIFS(Data_Revenus[Montant], Data_Revenus[Date], ">="&$B$2, Data_Revenus[Date], "<="&$B$3)
|
|
Format: # ##0 "€"
|
|
Police: Calibri 28pt Bold
|
|
Couleur: #2C3E50
|
|
```
|
|
|
|
### Cellule KPI - Variation
|
|
|
|
```
|
|
Cellule: D5
|
|
Formule: =D4 - CA_Mois_Precedent
|
|
Format: +# ##0 "€";-# ##0 "€"
|
|
Couleur: Vert si positif, Rouge si negatif
|
|
```
|
|
|
|
---
|
|
|
|
## 8. Raccourcis Formules
|
|
|
|
| Besoin | Formule courte |
|
|
|--------|----------------|
|
|
| CA total | `=SUM(Data_Revenus[Montant])` |
|
|
| Heures total | `=SUM(Data_Temps[Heures])` |
|
|
| Nb clients | `=COUNTA(Data_Clients[ClientID])` |
|
|
| Nb projets uniques | `=COUNTA(UNIQUE(Data_Temps[Projet]))` |
|
|
| Date min | `=MIN(Data_Temps[Date])` |
|
|
| Date max | `=MAX(Data_Temps[Date])` |
|
|
|
|
---
|
|
|
|
**Version:** 1.0
|
|
**Date:** 2025-12-30
|