Create Form Dynamically in VBA

B

Bret

Without going into alot of details I need to create thru code and dynamically
a FORM in Datasheet View with a recordsource is an exisiting query. Can this
be done in code on the fly. I also need code that deletes or purges the same
form object.

thanks for any help.
 
K

Klatuu

Why?
It is not a good idea.
Perhaps if you described what you want to do, we can help with a how.
 
B

Bret

I have a very involved form with multiple combo and list boxes. User selects
or multi-selects their desired options. From these I'm dynamically creating
a SQL string in code and using "querydef" to delete and create a new QUERY
object.

This query is the RECORDSOURCE of a listbox in the form that displays the
results. After query has new SQL string, I just repaint or requery the
listbox and new results are displayed. All works wonderfully.

Now my customer wants NOT A LISTBOX but a form or subform in Datasheet View
OR a Report or SubReport.
This is where the problem is. The FORM object doesn't SEEM to be able to
accept the new query (or new SQL string) from its original via code.
For example if a the displayed report has column headings of January2007 to
June2007 with calculated values and now the user Selects January2007 to
December2007, the form doesn't accept the new query as its RECORDSOURCE, the
report is filled with the error figures, it wants to be built from scratch.

Thus my request to build a form in code if possible, unless you have another
welcome option or no how to do this thru code.

thanks for your reply.
 
K

Klatuu

do you mean it is not accepting the SQL as the record source of the report or
the form object? Is the form object the main form or the subform?
I know it is possible to change the recordsource of a form in runtime, but I
think a report has to be in design view to change the record source.

If it is the report, try opening the report in design view, hidden, and
change the record source. the close it with asSave Yes, then run it again.
 
B

Bret

Yes the form is the subform.
How would I do your suggestion in code?
Do I use "DOCMD.OPENFORM(acDesign ) or DOCMD.OPENREPORT(acDesign,,,)?

thx
 
K

Klatuu

If you try to open a subform with the OpenForm method, it will open on it's
own, not in the main form's subform control.

If you are opening the form stand alone, not a subform, you can do one of
two things. You can create a stored query that would be the record source of
the form, modify it during runtime, then open the form. If the form is
alread open, you just set it's record source in code.

To use the querydef method:

Dim qdf As QueryDef
Dim strSQL As String

Set qdf = Currentdb.QueryDefs("MyQueryName")
strSQL = "Select Some fields from sometable where a field = something;"
qdf.SQL = strSQL
qdf.Close
Set qdf = Nothing
Docmd.OpenForm "AnyOleForm"

To change the recorord source of a open subform:

Me.MySubformControlName.Form.RecordSource = strSQL

Note that MySubformControlName is the name of the subform control on the
main form, not the name of the form being used as a subform.
 
G

George Nicholson

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
 
B

Bob Quintal

I have a very involved form with multiple combo and list boxes.
User selects or multi-selects their desired options. From these
I'm dynamically creating a SQL string in code and using "querydef"
to delete and create a new QUERY object.

This query is the RECORDSOURCE of a listbox in the form that
displays the results. After query has new SQL string, I just
repaint or requery the listbox and new results are displayed. All
works wonderfully.

Now my customer wants NOT A LISTBOX but a form or subform in
Datasheet View OR a Report or SubReport.
This is where the problem is. The FORM object doesn't SEEM to be
able to accept the new query (or new SQL string) from its original
via code. For example if a the displayed report has column
headings of January2007 to June2007 with calculated values and now
the user Selects January2007 to December2007, the form doesn't
accept the new query as its RECORDSOURCE, the report is filled
with the error figures, it wants to be built from scratch.

Thus my request to build a form in code if possible, unless you
have another welcome option or no how to do this thru code.

thanks for your reply.
What I think to be happening is that you change the field names
presented in the query
If you alias the fields to some constant names the form will work.

SELECT January07 as month1, February07 as Month2, ....

The problem is how to update the form's labels: the answer is to
include a field in the query that returns a starting date, which can
be used to calculate the required caption for each label, then set
the lblMonth3 caption = format(dateadd("m",2,startdate),"mmmmyy")
 

Ask a Question

Want to reply to this thread or ask your own question?

You'll need to choose a username for the site, which only take a couple of moments. After that, you can post your question and our members will help you out.

Ask a Question

Top