Thread: Problem with commit in function

Problem with commit in function

From
Mike Martin
Date:
I have the following function
-- FUNCTION: public.update_log()

-- DROP FUNCTION public.update_log();

CREATE OR REPLACE FUNCTION public.update_log(
)
    RETURNS void
    LANGUAGE 'sql'

    COST 100
    VOLATILE 
AS $BODY$

truncate table postgres_log_tmp  ;
COPY postgres_log_tmp FROM '/mnt/pgdata/data/log/postgresql-Mon.csv' WITH csv;
COPY postgres_log_tmp FROM '/mnt/pgdata/data/log/postgresql-Tue.csv' WITH csv;
COPY postgres_log_tmp FROM '/mnt/pgdata/data/log/postgresql-Wed.csv' WITH csv;
COPY postgres_log_tmp FROM '/mnt/pgdata/data/log/postgresql-Thu.csv' WITH csv;
COPY postgres_log_tmp FROM '/mnt/pgdata/data/log/postgresql-Fri.csv' WITH csv;
COPY postgres_log_tmp FROM '/mnt/pgdata/data/log/postgresql-Sat.csv' WITH csv;
COPY postgres_log_tmp FROM '/mnt/pgdata/data/log/postgresql-Sun.csv' WITH csv;
INSERT INTO postgres_log SELECT * from postgres_log_tmp ON CONFLICT(session_id, session_line_num) DO NOTHING;
--COMMIT;
truncate table postgres_log_tmp  ;

$BODY$;

ALTER FUNCTION public.update_log()
    OWNER TO postgres;

If I leave the second truncate statement nothing is written to postgres_log. I assume the insert doesnt finish

Any way to force it to finish before the truncation?

Re: Problem with commit in function

From
Christoph Moench-Tegeder
Date:
## Mike Martin (redtux1@gmail.com):

> Subject: Problem with commit in function

You can't commit inside a FUNCTION - and there's an obvious ERROR if
you try to do that: "invalid transaction termination".
Only since version 11 you can use a PROCEDURE and COMMIT/ROLLBACK
inside that - and the procedure must be written in PL/pgSQL (you
don't get transaction control in SQL procedures - but beside the
LANGUAGE marker, your code would be the same).
See
  https://www.postgresql.org/docs/current/static/sql-createprocedure.html
  https://www.postgresql.org/docs/current/static/plpgsql-transactions.html

> truncate table postgres_log_tmp  ;

You might want to look into temporary tables (perhaps even unlogged
ones) - that will save you the hassle of truncating (temporary tables
are even automatically removed), and with an unlogged temp table it
will save you some WAL I/O.

> --COMMIT;

So, is this on or not?
Oh, and please pay attention to the errors PostgreSQL throws at
you - they're significant.

Regards,
Christoph

-- 
Spare Space