Condensing several similar macros to 1 (if possible)

Bruce54

New Member
Joined
Aug 2, 2017
Messages
15
I have 8 macro buttons that simply change the value of one cell - [D13] to States ("NSW","QLD" ...)
When this happens (ignoring the other functions) the button text turns white (from Black)

all relevant code:
'------------------------------------------------------------------'
'Sub PCODES_Rectangle3_Click()
'ClearButtons
' If Not [D13] = " (NSW)" Then
' ActiveSheet.Shapes.Range(Array("Rectangle 3")).Select
' With Selection.ShapeRange.TextFrame2.TextRange.Font.Fill
' .ForeColor.ObjectThemeColor = msoThemeColorBackground1
' End With
' [D13] = " (NSW)"
' Else
' ClearButtons
' End If
'[B13].Activate
'End Sub
'
'Sub Rectangle7_Click()
'ClearButtons
' If Not [D13] = " (QLD)" Then
' [D13] = " (QLD)"
' ActiveSheet.Shapes.Range(Array("Rectangle 7")).Select
' With Selection.ShapeRange.TextFrame2.TextRange.Font.Fill
' .ForeColor.ObjectThemeColor = msoThemeColorBackground1
' End With
' Else
' ClearButtons
' End If
'[B13].Activate
'End Sub
'

'Sub Rectangle8_Click()
'ClearButtons
' If Not [D13] = " (VIC)" Then
' [D13] = " (VIC)"
' ActiveSheet.Shapes.Range(Array("Rectangle 8")).Select
' With Selection.ShapeRange.TextFrame2.TextRange.Font.Fill
' .ForeColor.ObjectThemeColor = msoThemeColorBackground1
' End With
' Else
' ClearButtons
' End If
'[B13].Activate
'End Sub
'
'Sub Rectangle10_Click()
'ClearButtons
' If Not [D13] = " (SA)" Then
' [D13] = " (SA)"
' ActiveSheet.Shapes.Range(Array("Rectangle 10")).Select
' With Selection.ShapeRange.TextFrame2.TextRange.Font.Fill
' .ForeColor.ObjectThemeColor = msoThemeColorBackground1
' End With
' Else
' ClearButtons
' End If
'[B13].Activate
'End Sub
'
'Sub Rectangle11_Click()
'ClearButtons
' If Not [D13] = " (NT)" Then
' [D13] = " (NT)"
' ActiveSheet.Shapes.Range(Array("Rectangle 11")).Select
' With Selection.ShapeRange.TextFrame2.TextRange.Font.Fill
' .ForeColor.ObjectThemeColor = msoThemeColorBackground1
' End With
' Else
' ClearButtons
' End If
'[B13].Activate
'End Sub
'
'Sub Rectangle12_Click()
'ClearButtons
' If Not [D13] = " (WA)" Then
' [D13] = " (WA)"
' ActiveSheet.Shapes.Range(Array("Rectangle 12")).Select
' With Selection.ShapeRange.TextFrame2.TextRange.Font.Fill
' .ForeColor.ObjectThemeColor = msoThemeColorBackground1
' End With
' Else
' ClearButtons
' End If
'[B13].Activate
'End Sub
'
'Sub Rectangle13_Click()
'ClearButtons
' If Not [D13] = " (TAS)" Then
' [D13] = " (TAS)"
' ActiveSheet.Shapes.Range(Array("Rectangle 13")).Select
' With Selection.ShapeRange.TextFrame2.TextRange.Font.Fill
' .ForeColor.ObjectThemeColor = msoThemeColorBackground1
' End With
' Else
' ClearButtons
' End If
'[B13].Activate
'End Sub
'
'Sub Rectangle14_Click()
'ClearButtons
' If Not [D13] = " (ACT)" Then
' [D13] = " (ACT)"
' ActiveSheet.Shapes.Range(Array("Rectangle 14")).Select
' With Selection.ShapeRange.TextFrame2.TextRange.Font.Fill
' .ForeColor.ObjectThemeColor = msoThemeColorBackground1
' End With
' Else
' ClearButtons
' End If
'[B13].Activate
'End Sub
'
'Sub ClearButtons()
'[D13] = ""
' ActiveSheet.Shapes.Range(Array("Group 15")).Select
' With Selection.ShapeRange.TextFrame2.TextRange.Font.Fill
' .ForeColor.ObjectThemeColor = msoThemeColorText1
' End With
'End Sub
'-----------------------------------------------------------'

I know this is simple stuff, but I'm a beginner, so any help would be appreciated ;)
 

Excel Facts

Last used cell?
Press Ctrl+End to move to what Excel thinks is the last used cell.
Hello, it will be along these lines:

Code:
Private Sub Rectangle_Click(strMatchText As String, strRectangle As String)
  If Me.Range("D13").Value <> strMatchText Then
    Me.Shapes(strRectangle).TextFrame2.TextRange.Font.Fill.ForeColor = msoThemeColorBackground1
    Me.Range("D13").Value = strMatchText
  Else
    Call ClearButtons
  End If
End Sub

Sub Rectangle7_Click()
  Call Rectangle_Click(" (QLD)", "Rectangle 7")
End Sub

Sub Rectangle8_Click()
  Call Rectangle_Click(" (VIC)", "Rectangle 8")
End Sub

' And so on...
 
Upvote 0

Forum statistics

Threads
1,215,422
Messages
6,124,811
Members
449,191
Latest member
rscraig11

We've detected that you are using an adblocker.

We have a great community of people providing Excel help here, but the hosting costs are enormous. You can help keep this site running by allowing ads on MrExcel.com.
Allow Ads at MrExcel

Which adblocker are you using?

Disable AdBlock

Follow these easy steps to disable AdBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the icon in the browser’s toolbar.
2)Click on the "Pause on this site" option.
Go back

Disable AdBlock Plus

Follow these easy steps to disable AdBlock Plus

1)Click on the icon in the browser’s toolbar.
2)Click on the toggle to disable it for "mrexcel.com".
Go back

Disable uBlock Origin

Follow these easy steps to disable uBlock Origin

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back

Disable uBlock

Follow these easy steps to disable uBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back
Back
Top