Custom Cell Format

honkin

Active Member
Joined
Mar 20, 2012
Messages
385
Office Version
  1. 2016
Platform
  1. MacOS
Hi have researched custom format of cells, but have not been able to find a response which deals with my issue.

Is it possible to have a cell display as 3*3, 4*4, 5*5 and so on? So regardless of what number is typed, it displays as number*number.

Is there as way for this to be done?

Thanks in advance
 

Excel Facts

When they said...
When they said you are going to "Excel at life", they meant you "will be doing Excel your whole life".
Hope I understood well,

you can try PowerQuery: Expression.Evaluate

[Table="width:, class:head"]
[tr=bgcolor:#FFFFFF][td=bgcolor:#5B9BD5]raw[/td][td=bgcolor:#70AD47]Evaluate[/td][/tr]

[tr=bgcolor:#FFFFFF][td=bgcolor:#DDEBF7]5*5[/td][td=bgcolor:#E2EFDA]
25​
[/td][/tr]

[tr=bgcolor:#FFFFFF][td]27-4[/td][td]
23​
[/td][/tr]

[tr=bgcolor:#FFFFFF][td=bgcolor:#DDEBF7]33/11[/td][td=bgcolor:#E2EFDA]
3​
[/td][/tr]

[tr=bgcolor:#FFFFFF][td]11+4.5[/td][td]
15.5​
[/td][/tr]

[tr=bgcolor:#FFFFFF][td=bgcolor:#DDEBF7]11*11[/td][td=bgcolor:#E2EFDA]
121​
[/td][/tr]
[/table]


or

defined name with VBA function Evaluate , eg. =EVALUATE(Sheet1!$A1) named as Result
then A1: 5*5
and in B1 use =Result
 
Upvote 0
Is it possible to have a cell display as 3*3, 4*4, 5*5 and so on? So regardless of what number is typed, it displays as number*number.
It is not possible to do this with a direct Custom Cell Format; however, we can create a Custom Cell Format in VBA event code that will do what you asked for.
Code:
Private Sub Worksheet_Change(ByVal Target As Range)
  Dim X As Long, Txt As String, Cell As Range
  If Not Intersect(Columns("[B][COLOR="#FF0000"]C[/COLOR][/B]"), Target) Is Nothing Then
    For Each Cell In Intersect(Columns("[B][COLOR="#FF0000"]C[/COLOR][/B]"), Target)
      Txt = Cell.Value
      For X = 1 To Len(Txt)
        If Mid(Txt, X, 1) Like "#" Then Mid(Txt, X) = "0"
      Next
      Cell.NumberFormat = Txt & "\*" & Cell.Value
    Next
  End If
End Sub
NOTE: You did not tell us what column you would be entering numbers into, so I guessed at Column C. If that is incorrect, change the red highlighted column letters to the correct column reference.

HOW TO INSTALL Event Code
------------------------------------
If you are new to event code procedures, they are easy to install. To install it, right-click the name tab at the bottom of the worksheet that is to have the functionality to be provided by the event code and select "View Code" from the popup menu that appears. This will open up the code window for that worksheet. Copy/Paste the event code into that code window. That's it... the code will now operate automatically when its particular event procedure is raised by an action you take on the worksheet itself. Note... if you are using XL2007 or above, make sure you save your file as an "Excel Macro-Enabled Workbook (*.xlsm) and answer the "do you want to enable macros" question as "yes" or "OK" (depending on the button label for your version of Excel) the next time you open your workbook.
 
Upvote 0
Thanks so much sandy, but was not trying to do a calculation, just format the number in the cell a particular way. Thanks so much for your reply

Hope I understood well,

you can try PowerQuery: Expression.Evaluate

[TABLE="class: head"]
<tbody>[TR="bgcolor: [URL=https://www.mrexcel.com/forum/usertag.php?do=list&action=hash&hash=FFFFFF]#FFFFFF[/URL] "]
[TD="bgcolor: #5B9BD5"][COLOR=[URL=https://www.mrexcel.com/forum/usertag.php?do=list&action=hash&hash=FFFFFF]#FFFFFF[/URL] ]raw[/COLOR][/TD]
[TD="bgcolor: #70AD47"][COLOR=[URL=https://www.mrexcel.com/forum/usertag.php?do=list&action=hash&hash=FFFFFF]#FFFFFF[/URL] ]Evaluate[/COLOR][/TD]
[/TR]
[TR="bgcolor: [URL=https://www.mrexcel.com/forum/usertag.php?do=list&action=hash&hash=FFFFFF]#FFFFFF[/URL] "]
[TD="bgcolor: #DDEBF7"]5*5[/TD]
[TD="bgcolor: #E2EFDA"]
25​
[/TD]
[/TR]
[TR="bgcolor: [URL=https://www.mrexcel.com/forum/usertag.php?do=list&action=hash&hash=FFFFFF]#FFFFFF[/URL] "]
[TD]27-4[/TD]
[TD]
23​
[/TD]
[/TR]
[TR="bgcolor: [URL=https://www.mrexcel.com/forum/usertag.php?do=list&action=hash&hash=FFFFFF]#FFFFFF[/URL] "]
[TD="bgcolor: #DDEBF7"]33/11[/TD]
[TD="bgcolor: #E2EFDA"]
3​
[/TD]
[/TR]
[TR="bgcolor: [URL=https://www.mrexcel.com/forum/usertag.php?do=list&action=hash&hash=FFFFFF]#FFFFFF[/URL] "]
[TD]11+4.5[/TD]
[TD]
15.5​
[/TD]
[/TR]
[TR="bgcolor: [URL=https://www.mrexcel.com/forum/usertag.php?do=list&action=hash&hash=FFFFFF]#FFFFFF[/URL] "]
[TD="bgcolor: #DDEBF7"]11*11[/TD]
[TD="bgcolor: #E2EFDA"]
121​
[/TD]
[/TR]
</tbody>[/TABLE]


or

defined name with VBA function Evaluate , eg. =EVALUATE(Sheet1!$A1) named as Result
then A1: 5*5
and in B1 use =Result
 
Upvote 0
Absolutely nailed in Rick. That works a treat so thank you very much.
It is not possible to do this with a direct Custom Cell Format; however, we can create a Custom Cell Format in VBA event code that will do what you asked for.
Code:
Private Sub Worksheet_Change(ByVal Target As Range)
  Dim X As Long, Txt As String, Cell As Range
  If Not Intersect(Columns("[B][COLOR=#FF0000]C[/COLOR][/B]"), Target) Is Nothing Then
    For Each Cell In Intersect(Columns("[B][COLOR=#FF0000]C[/COLOR][/B]"), Target)
      Txt = Cell.Value
      For X = 1 To Len(Txt)
        If Mid(Txt, X, 1) Like "#" Then Mid(Txt, X) = "0"
      Next
      Cell.NumberFormat = Txt & "\*" & Cell.Value
    Next
  End If
End Sub
NOTE: You did not tell us what column you would be entering numbers into, so I guessed at Column C. If that is incorrect, change the red highlighted column letters to the correct column reference.

HOW TO INSTALL Event Code
------------------------------------
If you are new to event code procedures, they are easy to install. To install it, right-click the name tab at the bottom of the worksheet that is to have the functionality to be provided by the event code and select "View Code" from the popup menu that appears. This will open up the code window for that worksheet. Copy/Paste the event code into that code window. That's it... the code will now operate automatically when its particular event procedure is raised by an action you take on the worksheet itself. Note... if you are using XL2007 or above, make sure you save your file as an "Excel Macro-Enabled Workbook (*.xlsm) and answer the "do you want to enable macros" question as "yes" or "OK" (depending on the button label for your version of Excel) the next time you open your workbook.

Can I assume this area will also work for conditional formatting? I have been racking my brain trying to work out how to do something and you have just given me an idea, but when I tried my code, it isn't how I would like.

I want to colour both a cell and text and bold the text based on what is in the cells. I wrote a formula and it works fine brilliantly. Here is the formula:-

Code:
=AND(TEXT($B2,"dd/mm/yyyy")=TEXT(TODAY(),"dd/mm/yyyy"), OR($A2="FA_Win_3", $A2="FA_Win_2"))
What I did was the select the range A2:A70, to make sure it has always got every row covered. So when the document is opened, if the date in B is today and the text in A is either of those you see, the cell is coloured green, the text white and bold.

The only issue is that other members of the team here in the office input data daily to the sheet and when that happens, the conditional formatting gets all messed up and no longer works on the full range it should. There might be 3 of 4 conditional format rules showing. You see, as each day transpires, old data is removed and new data pasted in. I need a way to protect A2:A70 so it acts regardless. That's why your method seemed perfect.

Here is what I did in VBA, but to no avail, so I have obviously done something wrong in the code. Sorry to ask for further assistance, but it is doing my head in. How does this look to your eye:-

Code:
Private Sub Worksheet_Change(ByVal Target As Range)

    ' This method has a drawback and is that the undo feature in this sheet no longer works (if you can live with it, no problem)
    ' Here is an option to bring it back: [URL]https://www.jkp-ads.com/Articles/UndoWithVBA04.asp[/URL]

    ' Define variables
    Dim targetRange As Range
    Dim formulaEval As String

    ' Define the Range. This is the range that receives the conditional format
    Set targetRange = Range("A2:A70")

    ' Define the formula evaluated by the conditional format (replace ; for ,)
    formulaEval = "=AND(TEXT(" B2 ",""dd/mm/yyyy"")=TEXT(TODAY(),""dd/mm/yyyy""), OR(A" 2 "=""FA_Win_3"", A" 2 "=""FA_Win_2""))"

    If Not Intersect(Target, targetRange) Is Nothing Then
        With Target
            .FormatConditions.Add Type:=xlExpression, Formula1:=formulaEval
            .FormatConditions(.FormatConditions.Count).SetFirstPriority

            ' This is where the format applied is defined (you can record a macro and replace the code here)
            With .FormatConditions(1).Interior
                .PatternColorIndex = xlAutomatic
                .Color = RGB(0, 176, 80)
                .TintAndShade = 0
                .Font.Color = RGB(255, 255, 255)
                .Font.Bold = True
            End With
            .FormatConditions(1).StopIfTrue = False
        End With
    End If

End Sub

Thanks so much in advance, Rick
 
Last edited:
Upvote 0

Forum statistics

Threads
1,223,236
Messages
6,170,915
Members
452,366
Latest member
TePunaBloke

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