RE: MS Access connection and insert issues

From: "Wal, Jan Tjalling van der" <jan_tjalling(dot)vanderwal(at)wur(dot)nl>
To: Evan Hallein <evan(dot)hallein(at)dbca(dot)wa(dot)gov(dot)au>, "pgsql-odbc(at)postgresql(dot)org" <pgsql-odbc(at)postgresql(dot)org>
Subject: RE: MS Access connection and insert issues
Date: 2023-11-27 10:22:50
Message-ID: AM0PR01MB5634D9FBD4CB731AE54DFF0FDDBDA@AM0PR01MB5634.eurprd01.prod.exchangelabs.com
Views: Raw Message | Whole Thread | Download mbox | Resend email
Thread:
Lists: pgsql-odbc

Hello Evan,

I work with a similar setup, with an Access-frontend to a PostgreSQL-backend.
The config-options are unreliable as far as my experience goes, I did point this out in the mailing-list a while back.
At the time for psqlodbc 13.02 against a psql 11-server.
Setting read-only is not working as an example.

My work-around for that is setting up user-roles on the postgres-server.
When a user opens a form I first check whether the role is read-only or has insert/update/delete-rights.
If the latter is detected, I use that to allow those actions on the form in MS-Access.
In an On-Load-action could be appropriate.

You could skip setting those rights on the form, but then the ro-users may think they can change things and try to.
With appropriate roles in place on the server, it will blocked there. Resulting in a cryptic error message appearing in Access. That is likely to cause your users to get confused. So I prefer to avoid that.

Access does not automatically know what happens on the server-side.
Your inserted records ends-up on the server. You probably need to do a .Refresh() or .Requery on the form to ensure that the values from the server are fetched and can be shown by Access. I often have one of these actions in the vba-code of a form after an insert or update of a records has been done.

BTW this is not unique to PostgreSQL, with an Oracle-backend the behaviour is very similar.

I hope these pointers help you to achieve your goals.

Best regards, Jan Tjalling van der Wal
Wageningen Marine Reseach (WMR) / formerly IMARES Institute for Marine Resources & Ecosystem Studies
Ankerpark 27, 1781 AG Den Helder Postbus 57, 1780 AB Den Helder
Tel. +31 (0)317-4 87147 # GSM. +31 (0)626120915 (privé) #
# Ma+Di Vr 09:00-18:00, Wo XX, Do+Vr 09:00-18:00
Jan_Tjalling(dot)vanderWal(at)wur(dot)nl<mailto:Jan_Tjalling(dot)vanderWal(at)wur(dot)nl>
From: Evan Hallein <evan(dot)hallein(at)dbca(dot)wa(dot)gov(dot)au>
Sent: Monday, November 27, 2023 2:56 AM
To: pgsql-odbc(at)postgresql(dot)org
Subject: MS Access connection and insert issues

Hi,

I am trying to migrate an old MS Access application with an SQL Server back end to PostgreSQL backend. I'm able to connect and read the data successfully, however there are some (related?) issues. Using version 16 of the 64bit unicode ODBC driver on windows 11 with postgres 14.9 (linux)

The first is that I don't seem to be able to set the ODBC driver options in Access using a connection string, they just seemed to get ignored. I have followed this: psqlODBC HOWTO - Access VBA (postgresql.org)<https://odbc.postgresql.org/howto-accessvba.html>
It connects, but whatever config options I put get ignored and the linked table manager in Access always shows this same connection string options: DRIVER={PostgreSQL Unicode(x64)};DATABASE=wamtram;SERVER=127.0.0.1;PORT=5432;UID=###;PWD=###;CA=d;A6={};A7=100;B0=254;B1=8190;BI=0;C2=;D6=-101;CX=1c3810489;A1=7.4

I've also tried using a DSN, but the same issue happens.

The second issue is to do with inserting records and getting an autoincrement ID back from the new record. The autoincremented ENTRY_BATCH_ID is always empty after inserting. I can see the record gets added to the database, but the record in Access in not updated with the new "ENTRY_BATCH_ID". If hard code an ENTRY_BATCH_ID it works. This is working with SQLServer.

This is the VBA Code:
--------------------
' Set the connections
Set MainConn = CurrentProject.Connection
UserConn.Open "Provider=Microsoft Office 12.0 Access Database Engine OLE DB Provider;Data Source=" & strFileName

' Start transaction
MainConn.BeginTrans

' Add a record for the batch
MainRs.Open "TRT_ENTRY_BATCHES", MainConn, adOpenDynamic, adLockOptimistic
MainRs.AddNew

MainRs!FILENAME = strFileName
MainRs!ENTRY_DATE = Date ' UserRs!ENTRY_DATE

MainRs.Update
lngEntryBatchID = MainRs!ENTRY_BATCH_ID '<------------- fails here, no value in ID and returns "record is deleted"
-------------------------------------

and this is the table schema:
------------------
CREATE TABLE IF NOT EXISTS dbo."TRT_ENTRY_BATCHES"
(
"ENTRY_BATCH_ID" integer NOT NULL DEFAULT nextval('"TRT_ENTRY_BATCHES_ENTRY_BATCH_ID_seq"'::regclass),
"ENTRY_DATE" timestamp with time zone,
"ENTERED_PERSON_ID" integer,
"FILENAME" character varying(255) COLLATE pg_catalog."default" DEFAULT NULL::character varying,
"COMMENTS" character varying(255) COLLATE pg_catalog."default" DEFAULT NULL::character varying,
CONSTRAINT "idx_237586_PK_TRT_ENTRY_BATCHES" PRIMARY KEY ("ENTRY_BATCH_ID")
)
-------------------------------

Any ideas? Is there config that I need to set, which I can't? I'm new to VBA, so maybe there is something I need to change?

thanks

--------------------------------

Evan Hallein

Senior Technical Officer

North West Shelf Flatback Turtle Conservation Program

https://flatbacks.dbca.wa.gov.au/

Department of Biodiversity, Conservation and Attractions

17 Dick Perry Av., Kensington, WA, 6151

Mob 0419 874 211

________________________________
This message is confidential and is intended for the recipient named above. If you are not the intended recipient, you must not disclose, use or copy the message or any part of it. If you received this message in error, please notify the sender immediately by replying to this message, then delete it from your system.

In response to

Browse pgsql-odbc by date

  From Date Subject
Next Message Sofia Barreto 2023-11-27 18:48:27 Windows 11 compatibility
Previous Message Evan Hallein 2023-11-27 01:55:45 MS Access connection and insert issues