Using MS Access with PostgreSQL Checkout our PostGIS in Action book 2nd Edition. First chapter is a free download

Postgres OnLine Journal

PostGIS in Action About the Authors Consulting



Thursday, January 31. 2008


Using MS Access with PostgreSQL

Printer Friendly
Recommended Books: Access 2007 - The Missing Manual Access 2007 for Dummies Access 2007 VBA Programming for Dummies

Many in the PostgreSQL community use Microsoft Access as a front-end to their PostgreSQL databases. Although MS Access is strictly a windows application and PostgreSQL has its roots in Unix, the two go well together. A large part of that reason is because the PostgreSQL ODBC driver is well maintained and has frequent updates. You can expect one new ODBC driver release every 4-6 months. There exist only 32-bit production quality drivers. The 64-bit driver is of alpha quality. In addition to other front-ends to PostgreSQL that utilize the ODBC driver used by Windows developers, there is VB 6 (VB.NET/C# use the ADO.NET driver also very well maintained), Visual FoxPro, Delphi, to name a few).

People who have never used Microsoft Access or anything like it and consider themselves hard-core programmers or database purists, dismiss Microsoft Access as a dangerous child's toy, causing nothing but grief when real programmers and database administrators have to debug the disorganized mess of amateurs. They dream of the day when this nuisance is rid of and their company can be finally under the strict bureaucratic control of well-designed apps that no one cares to use.

Beneath the croft of this dinkiness/dangerous toy is a RAD and Reporting tool that can connect to any database with an ODBC or ADO driver. It serves the unique niche of

  1. Empowering a knowledge worker/beginner programmer/DB user who is slowly discovering the wonders of relational databases and what time savings such a tool can provide.
  2. On the other side - it is inviting to the pragmatic (lazy) database programmer who has spent precious time to investigate its gems. The pragmatist sees it as a tool which provides a speedy development environment and intuitive reporting environment. It allows one to give more freedom to less experienced users, thus relieving one of tedious requests for information. By using it as a front-end to a strong server-side database such as PostgreSQL, it allows one to enforce a sufficient level of data integrity and control. The pragmatist realizes that often the best way to maintain order is to not fight disorder because the more you try to restrict people's freedoms, the craftier they get in devising ways of circumventing your traps. The pragmatic programmer also takes the view of Give a man a fish and he will pester you for more fish. Teach a man to fish and he will help you catch bigger fish.

In this article - we'll walk thru:
  1. How to install the PostgreSQL ODBC driver and gotchas to watch out for
  2. How to link to PostgreSQL tables and views via Linked tables
  3. Pass-thru queries - what they are and how to create them?
  4. How to export access tables and even other linked datasources to PostgreSQL - e.g. using MS Access as a simple exporting/importing tool
  5. Quick setup of a form that uses the new TSearch functionality in PostgreSQL 8.3

For this example we will be using Microsoft Access 2003, PostgreSQL 8.3 RC2. For the database, we will be using the pagila 0.10 database (8.3 version).

Installing PostgreSQL ODBC Driver

The latest PostgreSQL 32-bit ODBC Driver can be download by choosing a mirror from http://wwwmaster.postgresql.org/download/mirrors-ftp and then navigating to the pub/postgresql/odbc/versions/msi/ folder. The current version is psqlodbc_08_03_0100.zip which was released Jan-22-2008. For those who desperately need 64-bit ODBC, you can compile your own or try the AMD 64-bit test version.

  1. Unzip psqlodbc_08_03_0100.zip
  2. Run the psqlodbc.msi file (If you have an older version of the PostgreSQL driver, uninstall it first before installing the new one)

How to link to PostgreSQL tables and views via Linked tables

  1. Create a blank Access Database
  2. Go to Files->Get External Data->Linked Tables As shown below MS Access Linked Tables
  3. Click on drop down and switch to ODBC Datasources as shown here - MS Access Linked Tables ODBC
  4. Switch to File Datasource. Note we are using File DSN instead of Machine Datasource because File DSN string gets embedded in the MS Access Database, therefore you do not have to setup the DSN on each computer that will use the MS Access Database. Machine DSNs have to be setup on each individual pc. File DSNS are also normally kept in files that sit in C:\Program Files\Common Files\ODBC\Data Sources and this default path can be changed from ODBC manager to a Network location if you want users to be able to share File DSNs.
  5. Click New Button
  6. Select driver as shown here. PostgreSQL ODBC ANSI Note: in this picture we have selected the ANSI driver since our database is WIN-1252 encoded. Choose Unicode if your database encoding is UTF-8 or a non Latin Encoding, choose ANSI if your database encoding is SQL_ASCII, EUC_JP, BIG5,Shift-JIS, or a LATIN character set
  7. Click Next and type in a name ODBC Manager Connection Type name
  8. Click Next and fill in relevant server, db.
  9. Click the Connection button and uncheck Bools as char as shown ODBC Manager Connection Pg 1
  10. Click the Page 2 button and check True is -1, and uncheck updateable cursors as shown ODBC Manager Connection Pg 2 and then click OK
  11. Now select the tables you want and click Save Password.

    If you are missing primary keys on tables, Access will prompt you for what fields or set of fields you would like to use as the primary key. This doesn't make any structural changes to the actual table, but in the linked structure, Access will pretend this is the primary key and use that accordingly for table updates and such. This is particularly useful for views where the concept of primary keys does not exist and you want your updateable views to be updateable from Access. If you click OK or Cancel to the question without picking a set of fields, that table will be marked as readonly, which is the desired behavior for a lot of reporting views.

Pass-thru queries - what they are and how to create them

Access has a query feature called Pass-thru Queries available in the Query Designer. What this lets you do is pass a native PostgreSQL query directly to PostgreSQL so that it is not translated by the JET driver. Note pass-thru queries have visibility into the PostgreSQL db, and not your access database so don't expect to be using Access tables in them.

Pros
  • You can use native PostgreSQL functions and every other sweet function in PostgreSQL that Access has no clue what to do with such as full text search queries and Postgis spatial queries.
  • Skips the JET translation layer so is faster especially if you are joining with other tables in PostgreSQL
  • You can reference PostgreSQL tables and views you don't have linked in.
Cons
  • Unlike using linked tables in queries, you can't access any tables, jet functions, or custom access functions you have in your access database
  • Pass-thru queries are never updateable.

One example use is to for example use the sophisticated full text functionality in of PostgreSQL directly in MS Access. Below is an example using the Pagila database.

  • Create a new MS Access Query and select Design View and don't bother picking any tables
  • Under the Query menu choose -> SQL Specific -> Pass Through as shown SQL Pass Through
  • Type SELECT * FROM film WHERE fulltext @@ to_tsquery('fate&india'); in the query window
  • Click the Properties icon Properties Icon
  • In the Properties window - click the ... next to and pick the DSN you had created earlier and choose to save password as show Properties Window
  • Close the window save the query, call it qryFilmSearch and run

Using Microsoft Access as an Exporting/Importing tool

In addition to linking tables, Microsoft Access can be used as a simple conduit for importing and exporting data in and out of PostgreSQL.

To export data to PostgreSQL from any linked table or physical table in Microsoft Access - do the following:

  • Rename the table to the name you would like it named to.
  • Make sure the default schema of the user you are using in Postgres, is the schema you want to export the data to.
  • Go to File->Export-> Select ODBC Datasources which is way at the bottom and select the DSN you had created. One gotcha here is that PostgreSQL will maintain the casing of the fields in the table and the table name, so its best to rename all your fields to lowercase first so you don't have to be quoting them everytime you use them.

To import data from PostgreSQL into a Microsoft Access database for distribution etc. Do the following

  • Choose File->Get External Data->Import
  • Again select ODBC Datasource and use the DSN we created
  • Select the set of views, tables etc you want to import and then click OK.

Building a form with a Pass-thru Query that uses TSearch

In this little example, we'll demonstrate how to create simple form bound to a pass-thru query and programmatically change the pass-thru query via user input.

  • First bind the form to the passthru query you created above and just build the form with a wizard
  • Next place a text box on form and name it txtSearch
  • Next add a button on the form and name it cmdFindFilm and label it Find Film
  • Now put in code for the onclick event of the button that looks like this

    To programmatically change a pass thru query in response to a user's input so you can use it as a record source of a form, you can write something like this:
    Private Sub cmdFindFilm_Click()
     Dim qdf As Object
     Dim tSearchText As String
     If Me.txtSearch.Value > "" Then
     tSearchText = Replace(Replace(Me.txtSearch.Value, "", "|"), "'", "''")
     Set qdf = CurrentDb.QueryDefs("qryFilmSearch")
     qdf.SQL = "SELECT*FROMfilmWHEREfulltext@@to_tsquery('" & tSearchText & "')ORDERBYts_rank(fulltext,to_tsquery('" & tSearchText & "'))DESC,title"
     qdf.Close
     Me.Requery
     Else
     MsgBox "Pleasetypeinasearchcriteria"
     End If
    End Sub
    
    

  • Below is a snapshot of our finished form with a sample query we ran. Aint it cute. TSearch form in MS Access

    Gotchas

    File DSN does not let you change the port number

    I suspect this is a bug. When setting up file dsns via ODBC manager, for some reason the port is greyed out so if you are not running on the standard 5432 port, you have to edit the generated .dsn file manually. On top of that the file doesn't get generated with all the necessary info if a successful connection is not made. To get around this annoyance, you can go into .dsn file (in this case C:\Program Files\Common Files\ODBC\Data Sources\pagila.dsn) and change the port number before linking. Remember, once a table is linked with a file DSN, the actual DSN config gets encoded directly in the linked table meta data so you do not need to make the File DSN file accessible to users who use the access database. This is not true for Machine DSNs, only File DSNs.

    Below is something like what the DSN file should look like.

    
    [ODBC]
    DRIVER=PostgreSQL ANSI
    UID=pagila
    XaOpt=1
    LowerCaseIdentifier=0
    UseServerSidePrepare=0
    ByteaAsLongVarBinary=0
    BI=0
    TrueIsMinus1=1
    DisallowPremature=0
    UpdatableCursors=0
    LFConversion=1
    ExtraSysTablePrefixes=dd_
    CancelAsFreeStmt=0
    Parse=0
    BoolsAsChar=0
    UnknownsAsLongVarchar=0
    TextAsLongVarchar=1
    UseDeclareFetch=0
    Ksqo=1
    Optimizer=1
    CommLog=0
    Debug=0
    MaxLongVarcharSize=8190
    MaxVarcharSize=255
    UnknownSizes=0
    Socket=4096
    Fetch=100
    ConnSettings=
    ShowSystemTables=0
    RowVersioning=0
    ShowOidColumn=0
    FakeOidIndex=0
    Protocol=7.4-1
    ReadOnly=0
    SSLmode=disable
    PORT=5432
    SERVER=localhost
    DATABASE=pagila
    	
    	

    Tables Pre-fixed with schemas

    One of our pet peeves is that when you link all the tables you want it prefixes the tables with the schema and its not schema.tablename its schema_tablename e.g. public_actors.

    This is especially annoying if you use MS Access as a quick sql generator that you then use to paste back into your postgresql database as a view. This is an issue when you try to link any schema supporting database in MS Access. E.g. public_actors just is no good. Just actors works fine if you have default schemas in place or do not have a schema segmented database (e.g. everything is in public). Below is a VB subroutine we use to strip off the schema prefix.


    Sub StripSchemaName(schemaname As String)
     'schemanamethatprefixesthetablee.g.public
     '--EXAMPLEusefromimmediatewindow-
     '--StripSchemaName"public"
     Dim tdf As Object
     Dim i As Integer
     For Each tdf In CurrentDb.TableDefs
     If Left(tdf.Name, Len(schemaname)) = schemaname Then
     'plus2tostripthe_aswell
     tdf.Name = Mid(tdf.Name, Len(schemaname) + 2)
     End If
     Next
     MsgBox "Done"
    End Sub
    
    
    Dealing with Booleans

    One of the problems with using PostgreSQL as a back-end to MS Access is that Postgres has a true boolean data type where as MS Access has a Yes/No field which internally maps to -1 and 0. In earlier versions of PostgreSQL, there was an auto-cast in place to cast boolean to integer and vice-versa. This was later taken out. So now you get errors like operator does not exist boolean = integer when trying to do queries against these fields.

    Note the below example is useful for transparently casting Access's (True/False (-1/0) to PostgreSQL True/False)

    The below was adapted from Bahut ODBC PostgreSQL boolean mess. In Bahut's rendition he uses plpgsql functions. We revised to just use plain sql functions. The reason being is that in general when a function can be written in SQL, it performs much better than a plpgsql or other PL language written function, because the sql functions are more transparent to the Postgres query planner for appying indexes and so forth. In this case, the SQL variants are more succinct as well.

    
    CREATE OR REPLACE FUNCTION inttobool(integer, boolean) RETURNS boolean
    AS $$
     SELECT CASE WHEN 1ドル=0 and NOT 2ドル OR (1ドル0 and 2ドル) THEN true ELSE false END 
    $$
    LANGUAGE sql;
    CREATE OR REPLACE FUNCTION inttobool(boolean, integer) RETURNS boolean
    AS $$
     SELECT inttobool(2,ドル 1ドル);
    $$
    LANGUAGE sql;
    CREATE OR REPLACE FUNCTION notinttobool(boolean, integer) RETURNS boolean
    AS 
    $$
     SELECT NOT inttobool(2,ドル1ドル);
    $$
    LANGUAGE sql;
    CREATE OR REPLACE FUNCTION notinttobool(integer, boolean) RETURNS boolean
    AS $$
    	SELECT NOT inttobool(1,ドル2ドル);
    $$
    LANGUAGE sql;
    CREATE OPERATOR = (
    PROCEDURE = inttobool,
    LEFTARG = boolean,
    RIGHTARG = integer,
    COMMUTATOR = =,
    NEGATOR = 
    );
    CREATE OPERATOR  (
    PROCEDURE = notinttobool,
    LEFTARG = integer,
    RIGHTARG = boolean,
    COMMUTATOR = ,
    NEGATOR = =
    );
    CREATE OPERATOR = (
    PROCEDURE = inttobool,
    LEFTARG = integer,
    RIGHTARG = boolean,
    COMMUTATOR = =,
    NEGATOR = 
    );
    CREATE OPERATOR  (
    PROCEDURE = notinttobool,
    LEFTARG = boolean,
    RIGHTARG = integer,
    COMMUTATOR = ,
    NEGATOR = =
    );
    
    
    PostgreSQL is case-sensitive

    One of the most annoying things for people coming from a Windows environment is that PostgreSQL is case-sensitive whereas MS Access in-general is not (except when querying case sensitive databases). Explaining this to users and training them on case sensitivity is just a lot of hassle, not to mention the time-loss of having to upper case things. Hopefully this will change in the future so that PostgreSQL supports different collation depending field by field similar to the way SQL Server 2005 does. Needless to say, when running a query in MS Access, one has three options:

    1. Write your query along the lines of upper(somefield) LIKE UCase('abc%') and make sure you have a functional index on upper(somefield)
    2. Use the custom data type such as citext which you need to compile yourself.
    3. or Put functional upper(somefield) indexes on your common fields and use the freedom that PostgreSQL gives you to redefine varchar operators in your database by doing the below. NOTE that this gives you the benefit of not having to redefine varchar fields as citext or anything like that thus making it more portable to transfer back and forth between non-case sensitive dbs or use the same schema as non-case sensitive dbs. Note we couldn't do the below with text because that is defined high up and can not be overwritten. We can overwrite the behavior of varchars however because varchars get implicitly cast to text and use the text operators. By using PostgreSQL's operator overload feature, we can define special behavior for varchar when used in comparators. When Postgres sees there is such an operator, it will use that instead of cast varchar to text and using the default text operators. The downside is that this will not work with PostgreSQL text (NOTE: varchar in PostgreSQL/ANSI SQL maps to text in MS Access and text in PostgreSQL/ANSI maps to memo in MS Access - all very confusing) . In most cases this is a non-issue since most searches are done on short Access text fields rather than memo fields. NOTE: Use with caution. We haven't thoroughly tested this technique to catch all the possible situations where it can go wrong. It seems to behave correctly from our naive tests.
      		
      CREATE OR REPLACE FUNCTION ci_caseinsmatch(varchar, varchar) RETURNS boolean
      AS $$
       SELECT UPPER(1ドル)::text = UPPER(2ドル)::text;
      $$
      LANGUAGE sql
      IMMUTABLE STRICT;
      CREATE OPERATOR = (
      PROCEDURE = ci_caseinsmatch,
      LEFTARG = varchar,
      RIGHTARG = varchar,
      COMMUTATOR = =,
      NEGATOR = 
      );
      CREATE FUNCTION ci_like(varchar, varchar) RETURNS boolean
      AS $$
       SELECT UPPER(1ドル)::text LIKE UPPER(2ドル)::text;
      $$
      LANGUAGE sql;
      CREATE OPERATOR ~~(
       PROCEDURE = ci_like,
       LEFTARG = varchar,
       RIGHTARG = varchar,
       RESTRICT = likesel,
       JOIN = likejoinsel);
      		
      	
      Doing the above allows us to define a query like this in MS Access
      Case insensitive search Which yields: Johns and Farns

      And can now be written in SQL even in PgAdmin without all that messy upper lower stuff and still uses indexes if you have them defined on say upper(first_name) or doing range case-insensitive searches e.g. (customer.last_name between 'f' and 'h') :

      		
      			SELECT customer.*
      			FROM customer
      			WHERE customer.last_name 
      			Like 'Farns%' OR customer.first_name = 'Jim';
      		
      	

      Which will give you all customers with first name Jim or last name like Farns. Best of all, if you put in a functional index on last name and first name like below, it will use those indexes when doing equality or between ranges etc..


Trackbacks

GDAL/OGR2OGR for Data Loading
FWTools GIS Toolkit is a freely available open source toolkit for Windows and Linux that can do more than GIS tricks. It is a precompiled bundle of Open Source GIS tools. The FW comes from the initials of Frank Warmerdam, the originator of the tool
Weblog: Postgres OnLine Journal
Tracked: Feb 20, 15:22
PHP Gallery 2 for Picture Storage and Simple Document Management
What is PHP Gallery 2? PHP Gallery 2 is a web-based management system for storing pictures and other documents such as movies and flash files. While it is not designed for storing documents such as Microsoft Word or PDF, it serves as a simple storage c
Weblog: Postgres OnLine Journal
Tracked: May 20, 03:08
Weblog: areiaesal.wordpress.com
Tracked: Oct 04, 18:28
Weblog: forum.fachinformatiker.de
Tracked: Feb 01, 06:02
Weblog: www.pschwan.de
Tracked: Jul 15, 05:52
Weblog: www.pschwan.de
Tracked: Jul 16, 09:17
Weblog: www.postgresonline.com
Tracked: Sep 04, 00:21
Weblog: fatal-errors.com
Tracked: Aug 31, 17:58


Comments
Display comments as (Linear | Threaded)

Here is one other point about Access and ODBC linked booleans:

It seems that access sees ODBC nulls as false. When Access tries to update a field with a boolean null, the update will fail since ACCESS uses all of the table's old column values in the where clause of an update statement:

WHERE ...
AND boolean_field = 'false'::boolean
AND ...

However, since boolean_field actually is null the update fails.
#1 Richard Broersma Jr. on 2008年01月31日 13:42 (Reply)
Hi there,

I found your article very useful, it helped me a lot migrating my MS Access-backend to a real database. However, there are some tricky problems I am facing now:

some records are locked when I am (or someone else is) trying to edit them, whereby Access tells me that another user has been edited the record, which is why my changes cannot be saved. However, when I try to edit the same record with pgadmin (or funnily enough, with an updateble query in Access) I can edit anything I want.

Do have some hint for me what the problem might be?

thanks in advance,
Chris
#1.1 Chris on 2008年12月04日 09:55 (Reply)
Haven't come across this particular problem in PostgreSQL, but I have with linked tables to SQL Server where by to resolve I had to put in SQL Server's native timestamp (which is not a timestamp) field in there.

Take a look at Mike' suggestion -- he enabled Row Versioning and that seemed to solve his write conflicts - which is check box on the second page of ODBC config. If you are using file dsn, I think you will need to relink your tables.

Hope that helps,
Regina
#1.1.1 Regina on 2008年12月04日 10:52 (Reply)
Thanks for your advice, I will try to adapt the File DSN configuration. One thing I don't understand: I have migrated my postgres-DB to another server (identical structure and data), and there I am allowed to edit the records which I'm not allowed to in the old one. I have just checked the DSN configuration, and they are also identical. Do you happen to have any idea what that might be?
#1.1.1.1 Chris on 2008年12月05日 02:16 (Reply)
Hi again,

I have now tried to activate the row versioning, and now it works, thanks for your help!

Chris
#1.1.1.2 Chris on 2008年12月05日 02:21 (Reply)
Do you have any boolean columns in the write-conflict table? If so, instead using row versioning, make sure the boolean fields are never null, e.g. by issuing
ALTER TABLE your_table ALTER COLUMN your_boolean column SET DEFAULT FALSE;
UPDATE your_table SET your_boolean_column = FALSE WHERE your_boolean_column IS NULL;

Without row versioning enabled MS Access/ODBC driver doesn't use any highly-sophisticated versioning, but simply tries to find a record with exactly the same field values as the updated row (i.e. it issues sth like UPDATE SET ... WHERE col1=current_col1_value AND col2=current_col2_value ... AND colN = current_colN_value). If the record isn't found, access shows write-conflict message.

If your table doesn't contain any boolean columns you may look at the communication logs (enable it in the odbc configuration and relink the faulty table) to see why the update query issued by odbc/access doesn't find any record.

Row versioning is an inferior choice because it adds the xmin column to tables and the users shouldn't really mess with values in that column...
#1.1.1.2.1 Kamil Roman on 2009年03月19日 09:57 (Reply)
It's a shame Access hasn't been updated since the 7.4 series, which has long, white whiskers on it.
#2 David Fetter (Homepage) on 2008年01月31日 14:10 (Reply)
I always found it strange that the PostgreSQL ODBC driver says 7.4 on it even though well it obviously works with 8.0 versions and has been continuely updated. I think it is mostly a labeling issue on the ODBC driver but would be good PR to say 7.4-8.3 or something like that.

As far as functionality, I don't think it would make too much of a difference where ODBC is concerned.
#2.1 Regina on 2008年01月31日 15:15 (Reply)
A BIG thank you for this article. It saved me a ton of time while doing a migration from Access to Postgres
#3 Jan De Ryck on 2008年02月27日 17:01 (Reply)
Thanks Jan,
We are glad to hear you found it useful.
#3.1 Leo on 2008年02月27日 21:07 (Reply)
I think it's important to note that "Text as LongVarChar" should be Disabled.
#4 Anonymous on 2008年05月12日 22:43 (Reply)
I've had nothing but trouble with the "Bools as Char" option. If I uncheck it, as indicated here, I get the unpopular "Write Conflict" behaviour that I've seen elsewhere. It is fine with "Bool as Char" selected.

Does anyone else have this issue with Access 2000 and the 8.03.02.00 Unicode driver (or any other combination)? It could be a bug, but I'm not sure.
#5 Mike on 2008年06月19日 19:34 (Reply)
After much experimenting, I'll now highly recommend enabling the "Row Versioning" option. I've had some additional "Write Conflict" problems that are different than described above, and these issues all seem to be magically resolved in MS Access by enabling Row Versioning. I'd love to know what it is someday.
#5.1 Mike on 2008年07月16日 20:05 (Reply)
The .dsn file in C:\Program Files\Common Files\ODBC\Data Sources only has one entry namely:
[ODBC]
DRIVER=PostgreSQL ANSI

I wish to change the port that is used to access the database. Any ideas why the dsn file is missing its required entries. Using access 2002 SP3 .
#6 shaun on 2008年12月19日 05:43 (Reply)
Add to it

PORT=5433

or whatever your port is.

Might be better to just create another DSN though.

I think what you are looking at is a default DSN. Its best not to use that one. All the parameters not specified end up taking their defaults so the PORT would be 5432 when not specified.

You can simply createa new DSN by copying and pasting from that one or our example and adding in any extra things.

#6.1 Leo on 2008年12月20日 12:21 (Reply)
I experienced the following issue: Upon inserting a new row Access then displays every field in the row as "#Deleted". However the insert has not failed, requerying the table displays the newly inserted row.

This was due to the fact that after every insert operation access performs a query to verify the insert.

It attempts the verification twice, once using a SELECT based on the primary key, if that fails it performs a SELECT using every other field it inserted in the row. See:

http://support.microsoft.com/kb/128809

My issue arose because the primary key in the table is a sequence and access doesn't by default know the next value (it's generated by a trigger upon insert) so the first verification attempt failed.

The second verification also failed in my case as a different trigger on my table validates and changes one of the fields before insert (so the value in that field doesn't match the value Access used in the insert command).

I fixed this problem by writing a vba module that fetches the next sequence value from postgres with a passthrough query so Access can set the primay key directly rather than relying on the upon insert trigger. I followed the example on this website (it's for oracle but can very easily be modified for postgres):

http://www.techonthenet.com/access/queries/passthrough2.php
#7 drbob on 2009年03月13日 15:20 (Reply)
Inserting an Image!

Hi, I am using Ms Access as a front end to my Postgres DB. This tutorial is very useful.

One important thing not discussed here is how to insert/load images in a table. The BLOB or bytea type is somehow not recognized or incompatible with MS Access Object OLE. The column declared as BLOB in Postgres appear as binary in Ms Access.

Thanks for any advice.
#8 Dan on 2009年07月31日 04:06 (Reply)
Yea this tutorial is really helpfull. Thanks.

I have managed to create the ODBC link succesfully but my tables do not display in the list(for selection), i have checked priviledges and access is public, so what is wrong?

Thanks

Jepola
#9 Jepola on 2009年08月12日 06:07 (Reply)
Jepola,

You don't see any tables at all when you go to Get external data -> Linked Tables

Which version of Access are you using?
#9.1 Leo on 2009年08月12日 19:45 (Reply)
:-D Yeah!! Fabulous... just all i need... thanks a lot. ;-)
#10 Mr. P0nj@ on 2009年08月31日 20:00 (Reply)
Using ESF Database Migration Toolkit. It can migrating ms access to postgresql or back in 3 simple wizard steps without writing any sql script.

http://www.easyfrom.net/
#11 Martin (Homepage) on 2010年08月25日 00:14 (Reply)
Thank you for the helpful article.
Any idea why I am receiving an error message for "connection time out" while following the export procedure from MS Access 2007 to postgres database on a remote server? while it works fine for a postgres installation on localhost. I basically want to export large amount of data from access 2007 to remote installation of postgres database.

An advice will be highly appreciated.
#12 M.Saeed on 2011年02月17日 15:21 (Reply)
Unfortunately for large amounts of data across a not so local network, Access kind of sucks. I think its because of the way it tries to manage transactions so it can roll back the insert.

What we usually do for datasets above say 100,000 records is export the data out of access in CSV format and then use the built in psql or SQL in PostgreSQL to import the data. An easy step so you don't need to create the structure is to create a query that has a where clause such that you get no data and then export that. That will give you the structure in PostgreSQL. Then use the csv dump to import the data.

We have some examples of csv import on our cheatsheet I believe: http://www.postgresonline.com/journal/archives/177-PostgreSQL-9.0-Cheat-Sheet-Overview.html
#12.1 Leo on 2011年02月17日 15:56 (Reply)
Thank you for the reply. Being newbee, but an enthusiastic one, I want to know what is my mistake. Therefore to test this method for postgres on a remote ISP, I've created a new db with 1 table and 2 rows. Even then I get the same error "odbc call failed could not connect to the server error #101". I tried to use Access 2003 & Access 2007, no difference.

I suspect that I may be putting wrong Server while creating the file dsn in Access.

After login into the ISP via web, If I go to my databases section and select this pg database, it shows me some info. I saw a field called External Hostname = postgres32.xyzISP.net. I tried this as Server name but got above mentioned error. Then I went to phpPgAdmin page of my db and saw the IP address of database server and using it as Server in dsn creation, does not help either.

I tried to create Pass through query by giving in all the parameters but only the eror message changed to "ODBC--Connection to '{Postgres ANSI}givenIPaddress' failed". Any suggestion?
#12.1.1 M.Saeed on 2011年02月17日 19:02 (Reply)
I'm guessing your pg_hba.conf file is not set right on your postgreSQL server to allow connection from your local pc or there is a firewall in place on your ISP preventing port 5432 from being accessed directly. If you can't access the server from your local pgAdmin III then you wouldn't be able to either from MS Access. If you can via pgAdmin, then the pg_hba.conf is set up fine.

You can either change your pg_hba.conf if that is the problem or setup an ssh tunnel.
http://www.postgresonline.com/journal/archives/38-PuTTY-for-SSH-Tunneling-to-PostgreSQL-Server.html
#12.1.1.1 Regina on 2011年02月19日 14:18 (Reply)
It is not clear fron this article whether such an Access connection can be used for a data entry/edit tool, or just as a query tool.

Is it possible to connect to a Postgres DB using Access via ODBC as a data entry/edit tool?
#13 Brent Wood on 2011年05月03日 00:10 (Reply)
Brent,
Yes. In fact we have apps that do just that. The thing to be careful of is make sure to check the Row Version checkbox otherwise you sometimes get weird errors like record has already been edited.

The only problem is it can't make sense of specialty types like geometry, hstore etc so shows them as text (which for hstore is fine). You can only do PostgreSQL specific SQL via passthrus or build the logic in a view and link the view as a table in Access.

For simple edits appends etc its great, forms reports etc. its great.
#13.1 Regina on 2011年05月03日 01:17 (Reply)
Great tute, thanks. I got the latest ODBC driver and installed it. I successfully created a connection with Access 2007 creating a 2003 database on Win7 using your example DSN (I use a non-standard port) however, when I close the table and try to reopen it I get an ODBC error. It seems that it connects first time but never after the first time!! Any ideas?
#14 Colin (Homepage) on 2011年05月12日 23:36 (Reply)
when you link the table, make sure to choose -- Save Password. If you don't I think it just prompts for passwords for each table though not fails.
#14.1 Regina on 2011年05月13日 13:45 (Reply)
Has anyone got the version 8 ODBC to work with Access 2010?
#15 Shaun Wingrin on 2011年05月15日 07:00 (Reply)
Shaun,

Which ODBC are you referring to?

I've been using the ones here:
http://www.postgresql.org/ftp/odbc/versions/msi/

Though I think we've been using the 9.0 series with our MS Access 2010 64-bit install and haven't run into issues.
#15.1 Regina on 2011年05月16日 01:26 (Reply)
Tx...I've tried this driver, but it doesn't appear under the drivers listed in Setup ODBC DataSource. The version 9 64Bit one does.....

http://wwwmaster.postgresql.org/download/mirrors-ftp/odbc/versions/msi/psqlodbc_08_04_0200.zip
#16 Shaun Wingrin on 2011年05月16日 05:13 (Reply)
right there is your problem. If you have a 64bit Office, you need to use the 64bit driver versions which end in x64. That one is the 32bit driver.

There isn't a 64-bit 8... on the site so you need to use a 64bit 9... one. Note 9.. driver will work fine for lower versions of PostgreSQL so don't get thrown off by the version number.

http://ftp9.us.postgresql.org/pub/mirrors/postgresql/odbc/versions/msi/

So pick a -x64 one and you should be fine.
#16.1 Regina on 2011年05月16日 06:44 (Reply)
Tx. I tried it but get ODBC call failed:
The specified DSN contains an architecture mismatch between the Driver and Application (#0)
#17 Shaun Wingrin on 2011年05月16日 10:35 (Reply)
Where do you get that error? During install or when trying to create the DSN.

I assume when trying to create the DSN. How are you creating the DSN?

You definitely running Office 64-bit right?
#17.1 Regina on 2011年05月16日 17:07 (Reply)
It seems a reboot of PC was needed - I'm now finding the ver 8 file and linked fine with it.
Its probably not 64bit Access... although can't find where to check it. Tx 4 the reply.
#18 Shaun Wingrin on 2011年05月17日 03:16 (Reply)
Creating the boolean operators as suggested here, triggers BUG #7758 [1] of PostgreSQL, i.e. the output of pg_dump is broken.

The workaround is described on PostgreSQL documentation [2]:

omit the COMMUTATOR (NEGATOR) clause in the first operator that you define, and then provide one in the second operator's definition.


[1]: http://www.postgresql.org/message-id/41ED3F5450C90F4D8381BC4D8DF6BBDC729C317D@EXCHANGESERVER.ikoffice.de
[2]: http://www.postgresql.org/docs/9.2/static/xoper-optimization.html#AEN53307
#19 Marcello Nuccio (Homepage) on 2013年08月05日 12:31 (Reply)

Add Comment

E-Mail addresses will not be displayed and will only be used for E-Mail notifications.

To prevent automated Bots from commentspamming, please enter the string you see in the image below in the appropriate input box. Your comment will only be submitted if the strings match. Please ensure that your browser supports and accepts cookies, or your comment cannot be verified correctly.
CAPTCHA

 
 

Entry's Links

Quicksearch

Calendar

Mon Tue Wed Thu Fri Sat Sun
1 2 3 4 5 6 7
8 9 10 11 12 13 14
15 16 17 18 19 20 21
22 23 24 25 26 27 28
29 30          

Categories

Archives

Subscribe

Blog Administration

AltStyle によって変換されたページ (->オリジナル) /