Specify the fields and their data types, create primary and secondary indexes, set SubDataSheetName to None, allow text fields to accept zero length strings, set the CheckBox display for Yes/No fields, etc.
Procedure Name | Type | Description |
(Declarations) | Declarations | Declarations and private variables for the CCreateTableDAO class. |
Class_Terminate | Terminate | Clean up. |
CreateTable | Method | Specify the table name to create. |
IsTable | Method | Determine if the table already exists. |
DeleteTable | Method | Delete the table from the database. |
AddField | Method | Add a field to the table. |
AddFieldAutoNumber | Method | Add an autonumber long integer field to the table (it's always a required field). |
AddFieldCheckBox | Method | Add an Yes/No boolean field and set its display property to a check box. |
AddFieldHyperlink | Method | Add a hyperlink field to the table. |
AddFieldGeneral | Private | Main routine to add a field to the table with all the options. This is private since it's not necessary to expose it outside this class but can be changed to public if you want to call it directly. |
SaveTable | Method | After all the fields are added to the TableDef, save the table and optionally create a primary key for it. |
AddIndex | Method | After the table is saved, add a primary or secondary index to the table. |
SetFieldDefaults | Private | Go through all the fields and set the appropriate default settings. These could not be set until the table was created. |
SetObjectPropertyDAO | Private | Set the property value of an object and create it if it doesn't already exist. Used to set display type of a field, table properties, etc. This only works after the table is already saved. |
' Example of CCreateTableDAO ' ' To use this example, create a new module and paste this code into it. ' Two procedures are available to create tables with different options. ' Then run either of the procedures by putting the cursor in the procedure and press: ' F5 to run it, or ' F8 to step through it line-by-line (see the Debug menu for more options) Private Sub Example_CCreateTableDAO() ' Comments: Example of using the CCreateTableDAO class to create tables with indexes using VBA and VB6. ' This is an example of creating an error log table that can be used by the modErrorHandlerAccess module. Const cstrTable As String = "tblErrorLog" Const cstrKeyField As String = "ErrorID" Dim clsCreateTable As New CCreateTableDAO Dim fContinue As Boolean Dim strError As String With clsCreateTable ' If the table already exists, the CreateTable function will automatically replace it. ' In this example, we check to see if the table exists and prompt the user to overwrite it. You do not need to do this to create the table. fContinue = True If .IsTable(cstrTable) Then fContinue = (MsgBox(cstrTable & " table already exists, do you want to overwrite it?", vbQuestion + vbYesNo) = vbYes) End If If fContinue Then ' If the table exists, it's deleted and replaced by the new one strError = .CreateTable(cstrTable) If strError = "" Then ' Make the first field an autonumber field. We'll make this a primary key later. .AddFieldAutoNumber cstrKeyField ' Add the other standard fields that are dates, text, long integer, and memo types: .AddField "ErrorDate", dbDate .AddField "ErrorString", dbText, 255 .AddField "ErrorNumber", dbLong .AddField "ErrorLine", dbLong .AddField "ErrorProc", dbText, 255 .AddField "ErrorLog", dbMemo ' After all the fields are defined, save the table and specify the primary key strError = .SaveTable(cstrKeyField) If strError = "" Then DoCmd.OpenTable cstrTable MsgBox cstrTable & " was successfully created", vbInformation Else MsgBox cstrTable & " was not successfully created:" & vbCrLf & strError, vbCritical End If Else MsgBox cstrTable & " could not be created:" & vbCrLf & strError, vbCritical End If End If End With ' Clean up by closing the class Set clsCreateTable = Nothing End Sub Private Sub Example_CCreateTableDAO2() ' Comments: Example of using the CCreateTableDAO class to create a table with a variety of field types and multiple indexes ' This is an example of creating an error log table that can be used by the modErrorHandlerAccess module. Const cstrTable As String = "tblCreateTableDAO_Test" Const cstrKeyField As String = "ID" Dim clsCreateTable As New CCreateTableDAO Dim strError As String With clsCreateTable ' Unlike the previous example, this overwrites the existing table without prompting the user. strError = .CreateTable(cstrTable) If strError = "" Then ' Make the first field an autonumber field. We'll make this a primary key later. .AddFieldAutoNumber cstrKeyField ' Add the other standard fields that are dates, text, long integer, and memo types: .AddField "Long Text", dbText, 255 .AddField "Short Text", dbText, 10 .AddField "CreateDate", dbDate .AddField "Long Integer", dbLong .AddField "Double", dbDouble .AddField "Integer", dbInteger .AddField "Money", dbCurrency .AddField "Memo", dbMemo ' Add a Yes/No field (note that its defined by dbBoolean as there's no dbYesNo) .AddField "Status", dbBoolean ' Email field as a hyperlink, and set it to be required .AddFieldHyperlink "Email", True ' Attachment field .AddField "Files", dbAttachment ' After all the fields are defined, save the table and specify the primary key. Default settings for tables and fields are also applied. strError = .SaveTable(cstrKeyField) If strError = "" Then ' Create a secondary index on two fields strError = .AddIndex("EmailStatus", "Email,Status", False, True, True) End If If strError = "" Then DoCmd.OpenTable cstrTable MsgBox cstrTable & " was successfully created", vbInformation Else MsgBox cstrTable & " was not successfully created:" & vbCrLf & strError, vbCritical End If Else MsgBox cstrTable & " could not be created:" & vbCrLf & strError, vbCritical End If End With ' Clean up by closing the class Set clsCreateTable = Nothing End Sub
The source code in Total Visual Sourcebook includes modules and classes for Microsoft Access, Visual Basic 6 (VB6), and Visual Basic for Applications (VBA) developers. Easily add this professionally written, tested, and documented royalty-free code into your applications to simplify your application development efforts.
Total Visual SourceBook is written for the needs of a developer using a source code library covering the many challenges you face. Countless developers over the years have told us they learned some or much of their development skills and tricks from our code. You can too!
Supports Access/Office 2016, 2013, 2010 and 2007, and Visual Basic 6.0!
"The code is exactly how I would like to write code and the algorithms used are very efficient and well-documented."
Van T. Dinh, Microsoft MVP