Sub OterDoublonsLignes()
Dim chemin$, P As Range, t, i&, j As Byte, a(1 To 7), b(1 To 7)
Dim x$, test1 As Boolean, test2 As Boolean, fich$
chemin = ThisWorkbook.Path & "\" 'à adapter
Application.ScreenUpdating = False
Set P = [A1].CurrentRegion.Resize(, 8)
P.Sort [A1], xlAscending, [D1], , xlAscending, [H1], xlDescending, Header:=xlYes
t = P 'matrice, plus rapide
For i = UBound(t) To 2 Step -1
For j = 1 To 7
a(j) = Trim(t(i, j)): b(j) = Trim(t(i - 1, j))
Next
a(4) = ZerosNonSignificatifs(Replace(a(4), " ", ""))
b(4) = ZerosNonSignificatifs(Replace(b(4), " ", ""))
x = Replace(a(4), "-", "*-*")
test1 = Join(a) = Join(b)
test2 = True
fich = Dir(chemin & a(1) & " *phase*N°*" & x & "*.xls*")
Do While fich <> ""
fich = ZerosNonSignificatifs(LCase(Replace(fich, " ", "")))
If fich Like "*phasen°" & a(4) & ".xls*" Then test2 = False: Exit Do
fich = Dir
Loop
If test1 Or test2 Then P(i, 1) = Empty
Next
P.Sort [A1], xlAscending, Header:=xlYes 'lignes vides en bas du tableau
On Error Resume Next 's'il n'y a pas de ligne vide
P.Columns(1).SpecialCells(xlCellTypeBlanks).EntireRow.Delete
t = ActiveSheet.UsedRange 'mise à jour de l'ascenseur vertical
End Sub
Function ZerosNonSignificatifs(t$)
Dim i%
t = Chr(1) & t
For i = 2 To Len(t)
If Not Mid(t, i - 1, 1) Like "#" And Mid(t, i, 1) = "0" _
Then t = Application.Replace(t, i, 1, Chr(1))
Next
ZerosNonSignificatifs = Replace(t, Chr(1), "")
End Function