If you're testing for a numeric value, then don't put it in quotes. So, this
If Range("A36") = ">=3" Then
would be
If Range("A36") >= 3 Then
and so forth.
You should also target a specific worksheet with your Range.
Sub tedsst()
Dim wkSheet as Worksheet
Set wkSheet = ThisWorkbook.Worksheets("bANANAS")
Application.ScreenUpdating = False
wkSheet.Unprotect ("k0st4d")
'ActiveSheet.Unprotect Password:="123" '->>> How to say witch Sheet name i.e "Banana"
If wkSheet.Range("A36") >=3 Then
wkSheet.Range("B36").Locked = False
ElseIf wkSheet.Range("A36") <3 Then
wkSheet.Range("B36").Locked = True
End If
If wkSheet.Range("A37") >=3 Then
wkSheet.Range("B37").Locked = False
ElseIf wkSheet.Range("A37") <3 Then
wkSheet.Range("B37").Locked = True
End If
If wkSheet.Range("A38") >=3 Then
wkSheet.Range("B38").Locked = False
ElseIf wkSheet.Range("A38") <3 Then
wkSheet.Range("B38").Locked = True
End If
wkSheet.Protect ("k0st4d")
Application.ScreenUpdating = True
End Sub
You can shorten this code by assigning the locked value the value of testing the <3 in the cells. Like
Sub tedsst()
Dim wkSheet as Worksheet
Set wkSheet = ThisWorkbook.Worksheets("bANANAS")
Application.ScreenUpdating = False
wkSheet.Unprotect ("k0st4d")
'ActiveSheet.Unprotect Password:="123" '->>> How to say witch Sheet name i.e "Banana"
wkSheet.Range("B36").Locked = (wkSheet.Range("A36") < 3)
wkSheet.Range("B37").Locked = (wkSheet.Range("A37") < 3)
wkSheet.Range("B38").Locked = (wkSheet.Range("A38") < 3)
wkSheet.Protect ("k0st4d")
Set wkSheet = Nothing
Application.ScreenUpdating = True
End Sub
Because the locked property should be True if wkSheet.Range("A36") < 3 is true, you can just assign the value of the comparison directly and you don't need to have the if statements.