Controlling Fonts, Sizes and emphasis in a datasheet

WildWill

Board Regular
Joined
Sep 10, 2009
Messages
92
How can I control a datasheet to ensure that when other users add data to it, the data is automatically formatted to appear in (e.g.) Arial 10, Left alligned, and not bold?
 

Excel Facts

How to fill five years of quarters?
Type 1Q-2023 in a cell. Grab the fill handle and drag down or right. After 4Q-2023, Excel will jump to 1Q-2024. Dash can be any character.
You can format the worksheet to that specification, but the user will be able change the formats.

If data is pasted from another source, the formatting from that source may be carried through to Excel.

In Excel 2007 and later, you can protect the formatting so the user cannot change it.

You can write code for the Worksheet_Change event that will reapply the desired formatting whenever a cell is changed.
 
Upvote 0
Put this code in a standard module:
Code:
Sub SetFormat()
    'many options are commented out - uncomment them if you want tem to be applied.
    With ActiveSheet.Cells
        .HorizontalAlignment = xlLeft
        '.VerticalAlignment = xlBottom
        '.WrapText = False
        '.Orientation = 0
        '.AddIndent = False
        '.IndentLevel = 0
        '.ShrinkToFit = False
        '.ReadingOrder = xlContext
        '.MergeCells = False
        With .Font
            .Name = "Arial"
            .Size = 10
            .Bold = False
            '.Strikethrough = False
            '.Superscript = False
            '.Subscript = False
            '.OutlineFont = False
            '.Shadow = False
            '.Underline = xlUnderlineStyleNone
            '.ThemeColor = xlThemeColorLight1
            '.TintAndShade = 0
            '.ThemeFont = xlThemeFontNone
        End With
    End With
End Sub

Put this code in each worksheet codepage that you want to force formats on.
Code:
Private Sub Worksheet_Change(ByVal Target As Range)
    'Will trigger if the content of cells are changed
    SetFormat
End Sub
 
Private Sub Worksheet_activate()
    'Will trigger when a different worksheet is shown
    SetFormat
End Sub

Put this code in the ThisWorkbook codepage. It will format all worksheets before saving the workbook.
Code:
Private Sub Workbook_BeforeSave(ByVal SaveAsUI As Boolean, Cancel As Boolean)
    Dim lX As Long
    Dim sActiveSheet As String
    Application.EnableEvents = False
    Application.ScreenUpdating = False
    sActiveSheet = ActiveSheet.Name
    For lX = 1 To Worksheets.Count
        Worksheets(lX).Activate
        SetFormat
    Next
    Sheets(sActiveSheet).Activate
    Application.EnableEvents = True
    Application.ScreenUpdating = True
 
End Sub
 
Upvote 0
Another way, perhaps:
Code:
Private Sub Worksheet_Change(ByVal Target As Range)
    Target.Style = "Normal"
End Sub
 
Upvote 0

Forum statistics

Threads
1,215,066
Messages
6,122,947
Members
449,095
Latest member
nmaske

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