Forum

Add data to a cell ...
 
Notifications
Clear all

Add data to a cell in a range based on column value

3 Posts
2 Users
0 Reactions
89 Views
(@swallack202)
Posts: 77
Estimable Member
Topic starter
 

I have a workbook with several user forms/ I want to save their last used positions to a table called TABLE_FORM_POSITIONS (rather than read/write to the registry). 

As you can see from the attached sample XLS, I use the LAYOUT change event to save the form position. When the form is initialized/shown it retrieves the last saved position and opens it there.

So reading from the table is no problem (although there may be better ways than the one I'm using). The problem is WRITING to the table.  

I'm not sure the best way to save the form position to the table on the hidden sheet.

Thanks!

 
Posted : 20/06/2022 10:53 pm
(@debaser)
Posts: 836
Member Moderator
 

You could do something like this (I assume you will expand your table for the other two variables, but I haven't added the lines for those):

 

Sub SaveFormTopLeft(ByVal FormName As String, ByVal lLeft As Long, ByVal lTop As Long, ByVal lWidth As Long, ByVal lheight As Long)

' 1 - Look in the first column (Col A) of the "TABLE_FORM_POSITIONS" table
' 2 - Match the form name passed to this procedure as a parameter
' 3 - If match found then save lLeft value in table's 2nd column and lTop value in the 3rd column
' 4 - If no match then create a rown in the table so it will be found next time
Dim FormTable As ListObject
Set FormTable = shCounts.ListObjects("TABLE_FORM_POSITIONS")
Dim RowNum
RowNum = Application.Match(FormName, FormTable.ListColumns("Form").DataBodyRange, 0)
Dim DataRow As ListRow
If IsError(RowNum) Then ' form name not found
Set DataRow = FormTable.ListRows.Add
Else
Set DataRow = FormTable.ListRows(RowNum)
End If
With DataRow
.Range(1, FormTable.ListColumns("Form").Index).Value = FormName
.Range(1, FormTable.ListColumns("Left").Index).Value = lLeft
.Range(1, FormTable.ListColumns("Top").Index).Value = lTop
End With
End Sub

 
Posted : 21/06/2022 3:44 am
(@swallack202)
Posts: 77
Estimable Member
Topic starter
 

Thank you. I ended up with the following, and it works like a charm...

CODE IN A MODULE

Sub SaveFormTopLeft(ByVal FormName As String, ByVal lLeft As Long, ByVal lTop As Long, ByVal lWidth As Long, ByVal lheight As Long)
Dim FormTable As ListObject
Dim RowNum
Dim DataRow As ListRow
Set FormTable = shCounts.ListObjects("TABLE_FORM_POSITIONS")
RowNum = Application.Match(FormName, FormTable.ListColumns("Form").DataBodyRange, 0)
If IsError(RowNum) Then ' Form name not found in table
Call LockSheet(False, shCounts.Index) ' Unprotect sheet
Set DataRow = FormTable.ListRows.Add ' Add row
Call LockSheet(True, shCounts.Index) ' Protect sheet
Else
Set DataRow = FormTable.ListRows(RowNum)
End If
With DataRow
.Range(1, FormTable.ListColumns("Form").Index).Value = FormName
.Range(1, FormTable.ListColumns("Left").Index).Value = lLeft
.Range(1, FormTable.ListColumns("Top").Index).Value = lTop
End With
End Sub


Function GetFormLeft(ByVal FormName As String, ByVal dWidth As Double) As Double
Dim sRes As String
Dim dLeft As Double
Dim dCenter As Double
dCenter = Int(Application.Left + (Application.UsableWidth / 2) - (dWidth / 2))
On Error Resume Next ' Needed in case no value is found
' VLookup (value, array, index, match type)
sRes = Application.WorksheetFunction.VLookup(FormName, Range("TABLE_FORM_POSITIONS"), 3, False)
If Err.Number = 0 Then
dLeft = sRes
Else
dLeft = dCenter
End If
GetFormLeft = dLeft
End Function


Public Function GetFormTop(ByVal FormName As String, ByVal dHeight As Double) As Double
Dim sRes As String
Dim dTop As Double
Dim dCenter As Double
dCenter = Int(Application.Top + (Application.UsableHeight / 2) - (dHeight / 2))
On Error Resume Next ' Needed in case no value is found
' VLookup (value, array, index, match type)
sRes = Application.WorksheetFunction.VLookup(FormName, Range("TABLE_FORM_POSITIONS"), 2, False)
If Err.Number = 0 Then
dTop = sRes
Else
dTop = dCenter
End If
GetFormTop = dTop
End Function

* CODE IN THE FORM *

Private Sub UserForm_Activate()
' Restore last saved position
Me.Top = GetFormTop(Me.Name, Me.Height)
Me.Left = GetFormLeft(Me.Name, Me.Width)
End Sub

Private Sub UserForm_Initialize()
' Restore last saved position
Me.Top = GetFormTop(Me.Name, Me.Height)
Me.Left = GetFormLeft(Me.Name, Me.Width)
End Sub

Private Sub UserForm_Layout()
' Save position whenever the form moves
Call SaveFormTopLeft(Me.Name, Me.Left, Me.Top, Me.Width, Me.Height)
End Sub
 
Posted : 24/06/2022 4:29 pm
Share: