Learn Microsoft Access Advanced Programming Techniques, Tips and Tricks.

Showing posts with label Table. Show all posts
Showing posts with label Table. Show all posts

Uploading Comma delimited Text Data into Access Table-2

Introduction.

Last week we learned how to upload a simple list of names (separated with commas) from a text file into Microsoft Access Table.

Now, we will improve that program a little bit more to add a few fields (Name, Birthdate, Height, and Weight) to each record. The sample text file image is given below for reference.

The text file has a fixed number of items on a single line. All four items belong to a single record. In last week's example, we used a single column in the Access Table output, and the number of items on each line in the text file was different. Since, all the items belong to a single output column on Access Table we need to determine how many items are there in the x_Names Array, put by the Split() Function from a single line of text and we have used Ubound() Function to take the count of items in the output Array.

In this example, we have an output table with a fixed number of fields: Name, Birth Date, Height, and Weight. A sample image of the output table is given below:


The VBA Code.

VBA Code that uploads the text file into the access table is given below:

Public Function NamesList2()
'-----------------------------------------------------
'Utility: Creating Access Table from
'       : comma separated text data.
'Author : a.p.r.pillai
'Date   : May 2016
'Rights : All Rights Reserved by www.msaccesstips.com
'-----------------------------------------------------
Dim db As Database, rst As Recordset, tdef As TableDef
Dim strH As String, fld As Field, j As Integer
Dim x_Names As Variant, tblName As String, fldName As String
Dim txtfile As String

On Error GoTo NamesList2_err
tblName = "NamesList2"
txtfile = "d:\mdbs\Names2.txt" 'Make required changes 

'create the NamesList2 table
Set db = CurrentDb
Set tdef = db.CreateTableDef(tblName)
With tdef
  .Fields.Append .CreateField("Name", dbtext, 50)
  .Fields.Append .CreateField("BirthDate", dbDate)
  .Fields.Append .CreateField("Height", dbInteger)
  .Fields.Append .CreateField("Weight", dbInteger)
End With
db.TableDefs.Append tdef
db.TableDefs.Refresh

'Open the NamesList table to write names with the text file
Set rst = db.OpenRecordset(tblName)

'Open the Names2.txt file to upload data into the table
Open txtfile For Input As #1
'setup a loop to read the data till the end-of-file reached
Do While Not EOF(1)
'read the first line of items separated with commas and
'terminated with carriage return (Enter key)into variable strH
Line Input #1, strH
'extract each item separated with comma and load into the Array variable x_Names
x_Names = Split(strH, ",")

'Read each item from array elements
'and write into the NamesList2 table fields
With rst
    .AddNew
    ![Name] = x_Names(0)
    ![BirthDate] = x_Names(1)
    ![Height] = x_Names(2)
    ![Weight] = x_Names(3)
    .Update

End With
'Repeat till the End-Of-Text File is reached
Loop

NamesList2_Exit:
rst.Close
db.Close
Set rst = Nothing
Set db = Nothing
Exit Function

NamesList2_err:
If Err = 3010 Then 'Table already exists
  'continue executing from the next line onwards
  Resume Next
Else
  MsgBox Err & ": " & Err.Description, "NamesList2()"
  Resume NamesList2_Exit
End If
End Function

How IT Works.

As we did in the earlier example, first we are attempting to create a new access table with four fields. If the table creation process ends up with error code 3010 then the table already exists and continues to execute from the next line, skipping the table creation process. If it ends up with any other error code, then the program terminates. Opens the text file for reading the text data, each line at a time. The Split() function breaks up items in the line and loads them into the x_Names Array.

The next step is to add a new record into the access table, take each item from the array element and load it into the corresponding data field before updating them on the table. We know that each text line has four items and they are in which order. Only we need to know the array index numbers to read the items and load them into the fields. Split Function uses a zero-based index system to store the items in the array in memory. Since, we have only four items on a line the index numbers will be 0,1,2,3 to address each item in the array in sequence, Name, Birth Date, Height, and Weight shown in the program snippet given below.

With rst
    .AddNew
    ![Name] = x_Names(0)
    ![BirthDate] = x_Names(1)
    ![Height] = x_Names(2)
    ![Weight] = x_Names(3)
    .Update

End With

We can use the following code in place of the above code snippet:

With rst
    .AddNew
For j = 0 To UBound(x_Names)
    
    .Fields(j).Value = x_Names(j)
    
Next
    .Update
End With

The first code snippet is good for beginners and easy to understand. But, it is not an efficient method when more items are there on a text line to upload. The second code is more compact and doesn't address the field names directly. If any of the field names change at a later stage the first code snippet will run into an error but the second code will work without errors. The number of items on a line is also taken care of automatically. 

The first code cannot be used for a different table, but the second code snippet works for any table without change.

Share:

Apply Filter to Table directly

Introduction.

Normally we use Filter settings on Forms/Reports to extract records on specific conditions. This can be achieved in several ways like adding a WHERE Condition (without the clause WHERE) in the parameter setting of the OpenForm Macro Action or in the ApplyFilter Action parameter of a Macro or in the Docmd.OpenForm.

DoCmd.OpenForm "myForm", acNormal, , "EmployeeID Between 5 AND 10" command line in VBA) or Filter by Selection Form or use a Query as Record Source, and so on.

But, it is very unlikely that someone thinks of using the Filter Property of a Table directly to filter records when the Table opens in Datasheet View.  If you are working with someone else project and found a table showing only a few records in datasheet view, but you are told that the table is supposed to have hundreds of records in it and want to find out what happened to the rest of the records, then read on.

Setting Filter on Table.

We will explore how this trick works on a Table, for a change.  If you ever tried to set a Filter condition directly on a Form then you don't need any extra help to do this on your own.  To try out this we need some ready-made data from the Northwind sample database.  You may try it out with your own table as well.

  1. Import the Order Details  Table from the Northwind sample database.

  2. Open the Table in the Design view.

  3. Press F4 to display the Property Sheet of the Table.



    Table Property Sheet View.

  4. Find the Filter Property and type [Order ID] Between 35 AND 45 into the property (in Access2007). For earlier Access Versions type [OrderID] Between 10249 AND 10251.

  5. Set the Filter On Load property value to Yes.

  6. Save and close the Table Structure.

  7. Open the Table in Datasheet View to see the Filter in action.

The output records displayed are only of Order IDs between 35 and 45.  If you design a Quick Form or Report from this Table the Record Source property will be set with an SQL SELECT statement with the WHERE condition inserted from the Filter Property settings from the Table.  But, if you modify the Filter condition on the Table later don't expect to reflect that change on the Record Source SQL of Report or Form automatically.

Automating through VBA.

Like anything else in Microsoft Access If you would like to automate this through VBA, to change the filter criteria with the click of a button then here it is for you.  But, there is a small problem which I will tell you later so that you will know how important it is.  After all, it is about setting a simple filter condition on the Filter Property of the Table Structure.

We can address the Filter Property of a Table in VBA either through the front-door approach or through the backdoor method, so to speak.  The front-door approach is addressing the Filter Property through TableDef.Property.Filter path and another way are addressing it as Container.Documents.Properties.Filter path.  As you can see the second method is a little bit lengthy, that is why I call it the backdoor method.  We will try examples of both methods.

The second approach is very useful when working with Forms or Reports, like making a list of all Forms/Reports or wanting to change the name of a Form, etc. You can refer to an earlier blog post that creates a User-defined Property (Custom Property) to save values in it for opening a Form with the last-worked record to continue work from that record onwards, click here to find out more about it.

Example-1:

  1. Copy and Paste the following VBA Code into a Standard Module of your Database.
    Public Function TableFilter1(ByVal OrderStart As Long, ByVal OrderEnd As Long)
    Dim db As Database
    Dim Tbldef As TableDef
    
    Set db = CurrentDb
    
    Set Tbldef = db.TableDefs("Order Details")
    Tbldef.Properties("Filter").Value = "[Order ID] >=" & OrderStart & " AND [Order ID] <=" & OrderEnd
    Tbldef.Properties("FilterOnLoad").Value = True
    db.TableDefs.Refresh
    
    End Function
  2. Run the above sample Code from the Debug Window or from a Command Button Click Event Procedure like the sample run given below:

TableFilter1 35,45

NB: The above Code and sample run are given in the Order Details Table of Access2007.  If you are using an earlier Access Version then change the [Order ID] name to [OrderID] (i.e. Without the space between Order and ID) and in the sample run type TableFilter1 10249, 10251 instead of 35,45 for the OrderID range values.

If you have not tried out the manual filter method explained above or removed the filter criteria setting of the Filter Property then you will run into problems with the above program reporting an Error message stating that the Filter Property not found.

When you implement the VBA method see that an initial criteria setting is set in the Filter property of the Table.  Without the criteria setting the Filter Property will not be visible in VBA.

Example-2:

Copy and Paste the following VBA Code into the Standard VBA Module and run the Code in the same way as Example-1 with a different set of OrderIDs:

Public Function TableFilter2(ByVal OrderStart As Long, ByVal OrderEnd As Long)
Dim db As Database, ctr As Container, doc As Document

Set db = CurrentDb

Set ctr = db.Containers("Tables")
Set doc = ctr.Documents("Order Details")
doc.Properties("Filter").Value = "[Order ID] >=" & OrderStart & " AND [Order ID] <=" & OrderEnd
doc.Properties("FilterOnLoad").Value = True
doc.Properties.Refresh

End Function
Technorati Tags:
Share:

PRESENTATION: ACCESS USER GROUPS (EUROPE)

Translate

PageRank

Post Feed


Search

Popular Posts

Blog Archive

Powered by Blogger.

Labels

Forms Functions How Tos MS-Access Security Reports msaccess forms Animations msaccess animation Utilities msaccess controls Access and Internet MS-Access Scurity MS-Access and Internet Class Module External Links Queries Array msaccess reports Accesstips WithEvents msaccess tips Downloads Objects Menus and Toolbars Collection Object MsaccessLinks Process Controls Art Work Property msaccess How Tos Combo Boxes Dictionary Object ListView Control Query VBA msaccessQuery Calculation Event Graph Charts ImageList Control List Boxes TreeView Control Command Buttons Controls Data Emails and Alerts Form Custom Functions Custom Wizards DOS Commands Data Type Key Object Reference ms-access functions msaccess functions msaccess graphs msaccess reporttricks Command Button Report msaccess menus msaccessprocess security advanced Access Security Add Auto-Number Field Type Form Instances ImageList Item Macros Menus Nodes RaiseEvent Recordset Top Values Variables Wrapper Classes msaccess email progressmeter Access2007 Copy Excel Export Expression Fields Join Methods Microsoft Numbering System Records Security Split SubForm Table Tables Time Difference Utility WScript Workgroup database function msaccess wizards tutorial Access Emails and Alerts Access Fields Access How Tos Access Mail Merge Access2003 Accounting Year Action Animation Attachment Binary Numbers Bookmarks Budgeting ChDir Color Palette Common Controls Conditional Formatting Data Filtering Database Records Defining Pages Desktop Shortcuts Diagram Disk Dynamic Lookup Error Handler External Filter Formatting Groups Hexadecimal Numbers Import Labels List Logo Macro Mail Merge Main Form Memo Message Box Monitoring Octal Numbers Operating System Paste Primary-Key Product Rank Reading Remove Rich Text Sequence SetFocus Summary Tab-Page Union Query User Users Water-Mark Word automatically commands hyperlinks iSeries Date iif ms-access msaccess msaccess alerts pdf files reference restore switch text toolbar updating upload vba code