At times, you may need to transpose the data in a table or query so that
the field names are listed vertically down the left column and the data
extends across the page horizontally. For example, you may need to
transpose the data for a report or before exporting it to a text file. This
article shows you two methods that you can use to accomplish this task.
Method 1 shows you how you can export the data to Microsoft Excel,
transpose the data, and then import the result back into Microsoft Access.
Method 2 shows you how you can use a Visual Basic for Applications procedure to accomplish this task.
NOTE: Neither of the following methods works if you have more than 255 records because the maximum number of fields in a Microsoft Access table is 255.
Method 1 - Transpose the Data in Microsoft Excel
Export the Data to Microsoft Excel
- Start Microsoft Access and open your database. In the Database window, click the table or query that you want to export.
- On the File menu, click Export.
- In the Export Table To dialog box, select the version of Excel
to which you are exporting in the Save as type box.
- Specify the name and location of the file, and then click Export.
Transpose the Data in Microsoft Excel
- Start Microsoft Excel and open the spreadsheet that you created in step 5 of the "Export the Data to Microsoft Excel" section.
- Press CTRL+HOME to go to cell A1. Press CTRL+SHIFT+END to select all of the data.
- On the Edit menu, click Copy.
- On the Insert menu, click Worksheet.
- On the Edit menu, click Paste Special.
- In the Paste Special dialog box, click to select the Transpose check box, and then click OK.
- On the Format menu, point to Sheet, and then click Rename. Type a name for the sheet that contains the transposed data. If you want, click Save As on the File menu to export the data directly to text from Microsoft Excel.
- Save and close the workbook, and then quit Microsoft Excel.
Import the Data into Microsoft Access
NOTE: You can avoid the possibility of type conversion failures if you create a blank table that consists entirely of text fields and you append the data to that table rather than importing the data into a new table. However, you cannot append spreadsheet data to an existing table in a Microsoft Access.
- On the File menu, point to Get External Data, and then click Import.
- In the Import dialog box, click Microsoft Excel (*.xls) in the Files Of Type list.
- Locate and select the file that you saved after transposing the data in Microsoft Excel, and then click Import.
- On the first page of the Import Spreadsheet Wizard, click Show worksheets, and select the worksheet that contains the transposed data; click Next.
- Do not select the First Row Contains Column Headings check box on the second page of the Import Spreadsheet Wizard. Click Next.
- Click In A New Table, and then click Next twice.
- Click No Primary Key, and then click Next.
- Click Finish. The resulting table contains the transposed data.
Method 2 - Use a Custom Function to Transpose the Table
Microsoft provides programming examples for illustration only, without warranty either expressed or implied. This includes, but is not limited to, the implied warranties of merchantability or fitness for a particular purpose. This article assumes that you are familiar with the programming language that is being demonstrated and with the tools that are used to create and to debug procedures. Microsoft support engineers can help explain the functionality of a particular procedure, but they will not modify these examples to provide added functionality or construct procedures to meet your specific requirements.
- Create a new module in your database, and then type or paste the following procedure:
Function Transposer(strSource As String, strTarget As String)
Dim db As DAO.Database
Dim tdfNewDef As DAO.TableDef
Dim fldNewField As DAO.Field
Dim rstSource As DAO.Recordset, rstTarget As DAO.Recordset
Dim i As Integer, j As Integer
On Error GoTo Transposer_Err
Set db = CurrentDb()
Set rstSource = db.OpenRecordset(strSource)
rstSource.MoveLast
' Create a new table to hold the transposed data.
' Create a field for each record in the original table.
Set tdfNewDef = db.CreateTableDef(strTarget)
For i = 0 To rstSource.RecordCount
Set fldNewField = tdfNewDef.CreateField(CStr(i + 1), dbText)
tdfNewDef.Fields.Append fldNewField
Next i
db.TableDefs.Append tdfNewDef
' Open the new table and fill the first field with
' field names from the original table.
Set rstTarget = db.OpenRecordset(strTarget)
For i = 0 To rstSource.Fields.Count - 1
With rstTarget
.AddNew
.Fields(0) = rstSource.Fields(i).Name
.Update
End With
Next i
rstSource.MoveFirst
rstTarget.MoveFirst
' Fill each column of the new table
' with a record from the original table.
For j = 0 To rstSource.Fields.Count - 1
' Begin with the second field, because the first field
' already contains the field names.
For i = 1 To rstTarget.Fields.Count - 1
With rstTarget
.Edit
.Fields(i) = rstSource.Fields(j)
rstSource.MoveNext
.Update
End With
Next i
rstSource.MoveFirst
rstTarget.MoveNext
Next j
db.Close
Exit Function
Transposer_Err:
Select Case Err
Case 3010
MsgBox "The table " & strTarget & " already exists."
Case 3078
MsgBox "The table " & strSource & " doesn't exist."
Case Else
MsgBox CStr(Err) & " " & Err.Description
End Select
Exit Function
End Function
- To test the function, press CTRL+G. In the Immediate window, type the following line, and then press ENTER:
?Transposer("Suppliers","SuppliersTrans")