Here is some code I use to create quick and dirty generic data maintenance
forms in a batch for a set of tables at one time (those tables specified by
their entry in table sysTableXref). More than you asked for or probably
want. Please note that I use this while the app is in development, never in
live production. So, this addresses the "how do I" portion of your post.
Whether you *should* is a separate issue. There may be some obvious
references here to other functions, but they should be self explanatory.
I've actually edited some stuff out, but left a lot of it as-is, just as an
example of "how to do" a bunch of related stuff you didn't specifically ask
about.
These forms are intended to be presentable in either Datasheet or Single
form view, so more care is taken in spacing and formatting the controls and
labels than you would need if you are confining it to Datasheet view only.
Private Sub CreateFormsInBatch()
On Error GoTo ErrHandler
' Build new generic forms in a batch.(Quick & Dirty)
Dim frm As Form
Dim db As DAO.Database
Dim tdf As DAO.TableDef
Dim strName As String
Dim fld As DAO.Field
Dim intControlType As Integer
Dim ctlLabel As Control
Dim ctlData As Control
Dim intDataXleft As Integer
Dim intDataYtop As Integer
Dim intDataXwidth As Integer
Dim i As Integer
Set db = CurrentDb
For Each tdf In db.TableDefs
' Continue only if flag is set
If Nz(DLookup("[RebuildForm?]", "sysTableXref", "[TableName] = '" &
tdf.Name & "'"), "False") Eqv True Then
' Create new form.
Set frm = CreateForm
i = i + 1
' Set form properties.
With frm
.RecordSource = tdf.Name
' Set default view to datasheet view
.DefaultView = 2
.DividingLines = False
.RecordSelectors = False
.AllowDesignChanges = False
' Set name for new form
strName = "frm" & Mid$(tdf.Name, 4, 20)
.Caption = strName
.AllowPivotChartView = False
.AllowPivotTableView = False
.AutoCenter = True
.AutoResize = True
.ShortcutMenu = True
.ShortcutMenuBar = "CustomShortcut"
intDataXleft = 2000
intDataYtop = 100
For Each fld In tdf.Fields
' Set positioning values for new controls.
On Error Resume Next
intControlType = fld.Properties("DisplayControl")
If Err.Number <> 0 Then
' An error was raised because the property doesn't
exist for this field.
' therefore, the field is still the default: a text
box.
intControlType = acTextBox
End If
On Error GoTo ErrHandler
Select Case intControlType
Case acTextBox
If fld.Type = dbText Then
' Contains a text field: allocate roughly 75
twips per character. 1440 = 1 inch
If fld.Size > 20 Then
intDataXwidth = (1.5 * 1440) ' 1.5
inches
Else
intDataXwidth = (fld.Size * 75)
If intDataXwidth < 800 Then
intDataXwidth = 800
End If
Else
intDataXwidth = (1.5 * 1440) ' 1.5 inches
End If
Case Else
' Not a text box
intDataXwidth = (1.5 * 1440) ' 1.5 inches
End Select
' Create bound control of designated type in detail
section.
Set ctlData = CreateControl(frm.Name, intControlType, ,
"", fld.Name, _
intDataXleft, intDataYtop, intDataXwidth)
ctlData.TextAlign = 1 ' Left align
ctlData.Name = "ctl" & fld.Name
' Create child label control for text box.
Set ctlLabel = CreateControl(frm.Name, acLabel, , _
ctlData.Name, fld.Name, 50, intDataYtop, 1850)
ctlLabel.Width = 1850
ctlLabel.TextAlign = 3 'Right align
ctlLabel.Name = "lbl" & fld.Name
Select Case fld.Name
Case "AddedBy"
.BeforeUpdate =
"=AddTimestampToRecord([ctlAddedBy])"
Case Else
' Do nothing
End Select
Select Case Left$(fld.Name, 5)
' Format AddedBy/On and ChangedBy/On controls
Case "Added", "Chang"
ctlData.Enabled = False
ctlData.Locked = True
ctlData.SpecialEffect = 0 'Flat
ctlData.BorderStyle = 0 'None
ctlData.BackColor = glngGrayBackColor
Case Else
End Select
If (fld.Attributes And dbAutoIncrField) Then
' field is an autonumber field
ctlData.Enabled = False
ctlData.Locked = True
ctlData.BackColor = glngGrayBackColor
End If
intDataYtop = intDataYtop + 300
Next fld
End With
DoCmd.Save , strName
DoCmd.Close acForm, strName, acSaveYes
DoEvents
End If
Next
MsgBox "Complete: " & i & " forms created."
ExitHere:
Set fld = Nothing
Set tdf = Nothing
Set db = Nothing
Exit Sub
ErrHandler:
Select Case Err.Number
Case 2501 'Ignore: Save function canceled by user
DoCmd.Close , , acSaveNo
Resume Next
Case 438 'Ignore: Object doesn't support this property/method.
' Possible cause: trying to apply TextAlign to a checkBox, etc.
Resume Next
Case Else
Call ErrorLog(mModuleName & ".CreateFormsInBatch")
Resume ExitHere
End Select
End Sub