OLE DB Provider for Jet

Accessing and Changing Relational Data

Accessing and Changing Relational Data

OLE DB Provider for Jet

The Microsoft® OLE DB Provider for Jet provides an OLE DB interface to Microsoft Access databases, and allows Microsoft SQL Server™ 2000 distributed queries to query Access databases.

To create a linked server to access an Access database

  1. Execute sp_addlinkedserver to create the linked server, specifying Microsoft.Jet.OLEDB.4.0 as provider_name, and the full path name of the Access .mdb database file as data_source. The .mdb database file must reside on the server. data_source is evaluated on the server, not the client, and the path must be valid on the server.

    For example, to create a linked server named Nwind that operates against the Access database named Nwind.mdb in the C:\Mydata directory, execute:

    sp_addlinkedserver 'Nwind', 'Access 97', 'Microsoft.Jet.OLEDB.4.0', 
        'c:\mydata\Nwind.mdb'
    
  2. To access an unsecured Access database, SQL Server logins attempting to access an Access database should have a login mapping defined to the username Admin with no password.

    This example enables access for the local user Joe to the linked server named Nwind.

    sp_addlinkedsrvlogin 'Nwind', false, 'Joe', 'Admin', NULL
    

    To access a secured Access database, configure the registry (using the Registry Editor) to use the correct Workgroup Information file used by Access. Use the Registry Editor to add the full path name of the Workgroup Information file used by Access to this registry entry:

    HKEY_LOCAL_MACHINE\SOFTWARE\Microsoft\Jet\4.0\Engines\SystemDB
    

    After the registry entry is configured, use sp_addlinkedsrvlogin to create login mappings from local logins to Access logins:

    sp_addlinkedsrvlogin 'Nwind', false, 'Joe',
                            'AccessUser', 'AccessPwd'
    

Access databases do not have catalog and schema names. Therefore, tables in an Access-based linked server can be referenced in distributed queries using a four-part name of the form linked_server...table_name.

This example retrieves all rows from the Employees table in the linked server named Nwind.

SELECT * 
FROM Nwind...Employees

To create a linked server against an Excel spreadsheet:

The Microsoft OLE DB Provider for Jet 4.0 can be used to access Microsoft Excel spreadsheets.

  • To create a linked server that accesses an Excel spreadsheet, use the format of this example.
    sp_addlinkedserver N'Excel', N'Jet 4.0',
                       N'Microsoft.Jet.OLEDB.4.0',
                       N'c:\data\MySheet.xls', NULL, N'Excel 5.0'
    GO
    sp_addlinkedsrvlogin N'Excel', false, sa, N'ADMIN', NULL
    GO
    
  • To access data from an Excel spreadsheet, associate a range of cells with a name. A named range can be accessed by using the name of the range as the table name. The following query can be used to access a named range called SalesData using the linked server set up in the previous example.
    SELECT *
    FROM EXCEL...SalesData
    GO
    

    When you insert a row into a named range of cells, the row will be added after the last row that is part of the named range of cells. Thus, if you want to insert row rA after the column heading, associate the column heading cells with a name and use that name as the table name. The range of cells will grow automatically as rows are inserted.

To set up a linked server against a formatted text file:

Microsoft OLE DB Provider for Jet can be used to access and query text files.

  • To create a linked server for accessing text files directly without linking the files as tables in an Access .mdb file, execute sp_addlinkedserver, as in this example.

    The provider is Microsoft.Jet.OLEDB.4.0 and the provider string is 'Text'. The data source is the full path name of the directory that contains the text files. A schema.ini file, which describes the structure of the text files, must exist in the same directory as the text files. For more information about creating a schema.ini file, see the Jet Database Engine documentation.

    --Create a linked server.
    EXEC sp_addlinkedserver txtsrv, 'Jet 4.0', 
        'Microsoft.Jet.OLEDB.4.0',
        'c:\data\distqry',
        NULL,
        'Text'
    GO
    
    --Set up login mappings.
    EXEC sp_addlinkedsrvlogin txtsrv, FALSE, NULL, Admin, NULL
    GO
    
    --List the tables in the linked server.
    EXEC sp_tables_ex txtsrv
    GO
    
    --Query one of the tables: file1#txt
    --using a 4-part name. 
    SELECT * 
    FROM txtsrv...[file1#txt]