macro for cell border only works separately

nikaleya

New Member
Joined
Feb 15, 2021
Messages
13
Office Version
  1. 365
Platform
  1. Windows
Hi everyone,

I'm currently creating an input form for projects. The idea is to save the data put in (sheet "form") to a database (sheet "database") via VBA. To prevent the cells in the database to get formatted in any way, I only copy the values from the form. So far, so good. To have a "clean" database only the cells with values should have a border around. To try this, I created a separate macro, and this works fine. If I copy the code to the main sub for "copytodatabase", I get an error: Method 'Range' of object '_Worksheet' failed.

Code for the database:

VBA Code:
Sub copytodatabase()

Dim wb As Workbook: Set wb = ThisWorkbook
Dim form As Worksheet: Set form = wb.Worksheets("Form")
Dim database As Worksheet: Set database = wb.Worksheets("Database")
Dim range As String
Dim column As Integer
Dim lastentry, newentry As Integer

lastentry = database.Cells(Rows.Count, 1).End(xlUp).Row '(last row in database)
newentry = lastentry + 1 '(row for new entry)

'Project Number
range = "Input_ProjectNumber"
column = 1
database.Cells(newentry, column).Value = form.range(range).Value
'...and so on

Code for formatting the cells:

VBA Code:
Sub formatdatabase()

Dim wb As Workbook: Set wb = ThisWorkbook
Dim database As Worksheet: Set database = wb.Worksheets("Database")
Dim lastrow As Integer

lastrow = database.Cells(Rows.Count, 1).End(xlUp).Row

'Disable wrap text
database.range(Cells(2, 1), Cells(lastrow, 40)).WrapText = False

'cell borders
With database.range(Cells(2, 1), Cells(lastrow, 40))
    .Borders(xlEdgeBottom).LineStyle = XlLineStyle.xlContinuous
    .Borders(xlEdgeLeft).LineStyle = XlLineStyle.xlContinuous
    .Borders(xlEdgeRight).LineStyle = XlLineStyle.xlContinuous
    .Borders(xlEdgeTop).LineStyle = XlLineStyle.xlContinuous
    .Borders(xlInsideVertical).LineStyle = XlLineStyle.xlContinuous
    .Borders(xlInsideHorizontal).LineStyle = XlLineStyle.xlContinuous
    
End With

If I first run "copytodase" and then "formatdatabase" everything works and there is no error. If I use the call command within the first code, I get the error. Why is this happening? What am I missing?

Many thanks for your help!

Nika
 

Excel Facts

Waterfall charts in Excel?
Office 365 customers have access to Waterfall charts since late 2016. They were added to Excel 2019.
Try this

Rich (BB code):
Sub formatdatabase()

Dim wb As Workbook: Set wb = ThisWorkbook
Dim database As Worksheet: Set database = wb.Worksheets("Database")
Dim lastrow As Integer

lastrow = database.Cells(database.Rows.Count, 1).End(xlUp).Row

'Disable wrap text
database.Range(database.Cells(2, 1), database.Cells(lastrow, 40)).WrapText = False

'cell borders
With database.Range(database.Cells(2, 1), database.Cells(lastrow, 40))
    .Borders(xlEdgeBottom).LineStyle = XlLineStyle.xlContinuous
    .Borders(xlEdgeLeft).LineStyle = XlLineStyle.xlContinuous
    .Borders(xlEdgeRight).LineStyle = XlLineStyle.xlContinuous
    .Borders(xlEdgeTop).LineStyle = XlLineStyle.xlContinuous
    .Borders(xlInsideVertical).LineStyle = XlLineStyle.xlContinuous
    .Borders(xlInsideHorizontal).LineStyle = XlLineStyle.xlContinuous
End With

End Sub

I suspect that sheet "Database" is not the active sheet when the macro is run - so VBA needs additional help
 
Upvote 0
Solution
I knew I was missing something!
Many thanks, works perfectly! (y)
 
Upvote 0
@nikaleya, you can shorten all those Borders lines down to
VBA Code:
database.Range(database.Cells(2, 1), database.Cells(lastrow, 40)).Borders.LineStyle = xlContinuous
 
Upvote 0

Forum statistics

Threads
1,213,536
Messages
6,114,208
Members
448,554
Latest member
Gleisner2

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