Re: Functions, savepoints, autocommit = I am confused !

From: Adrian Klaver <adrian(dot)klaver(at)aklaver(dot)com>
To: Tim Smith <randomdev4+postgres(at)gmail(dot)com>
Cc: pgsql-general <pgsql-general(at)postgresql(dot)org>
Subject: Re: Functions, savepoints, autocommit = I am confused !
Date: 2015-06-26 18:29:03
Message-ID: 558D99EF.7090701@aklaver.com
Views: Raw Message | Whole Thread | Download mbox | Resend email
Thread:
Lists: pgsql-general

On 06/26/2015 10:49 AM, Tim Smith wrote:
>>
>> Did not see the strict. In any case I thought cleanSessionTable was cleaning
>> out app_security.app_sessions not app_security.app_val_session_vw.
>
> Yes. cleanSessionTable does the actual cleaning.
>
> The point of the select from app_security.app_val_session_vw is that
> if the session is valid, the function returns a JSON containing
> pertinent information relating to the session.
>
>
>>
>> Assuming something else is going you have two options(sense a theme?):
>>
>> 1) Remove the strict and do as I suggested in the previous post.
>>
>> 2) Move the count and IF before the select * into .. and then do what you
>> want.
>>
>
> So are you saying I need to do both this counting stuff AND the "ask
> for forgiveness", I thought you were suggesting mutuallly exclusive
> options earlier ?

Yes, they are different ways of approaching the problem.
>
> I'll work on integrating the count stuff now, but I still don't
> understand why a BEGIN subblock still gets rolled back.
>
> This is on 9.4.4 if it makes any difference, by the way.
>
>
>>>> 2) Act and then ask for forgiveness.
>>>>
>
> Regarding this part, I have changed to RAISE NOTICE and added a return
> to the bottom of the Pl/PGSQL.
>
> The function does not abort now, I get a simple :
>
> NOTICE: Failed to validate session for session XYZ (SQLSTATE: P0002
> - SQLERRM: query returned no rows)
> HINT: Database error occured (sval fail)
> validatesession
> -----------------
> [false]
> (1 row)
>
>
> But the problem persists in that the delete still gets rolled back,
> despite it being in its own sub block.

I knew I was missing something:(
http://www.postgresql.org/docs/9.4/interactive/plpgsql-control-structures.html#PLPGSQL-ERROR-TRAPPING

"When an error is caught by an EXCEPTION clause, the local variables of
the PL/pgSQL function remain as they were when the error occurred, but
all changes to persistent database state within the block are rolled
back. As an example, consider this fragment:"

So I would try
CREATE FUNCTION app_security.validateSession(p_session_id
app_domains.app_uuid,p_client_ip inet,p_user_agent
text,p_forcedTimeout bigint,p_sessionTimeout bigint) RETURNS json AS
$$
DECLARE
v_now bigint;
v_row app_security.app_val_session_vw%ROWTYPE;
v_json json;
BEGIN

BEGIN
perform app_security.cleanSessionTable(p_forcedTimeout,p_sessionTimeout);
EXCEPTION
WHEN OTHERS THEN
RAISE EXCEPTION 'Failed to clean session table % (SQLSTATE: % -
SQLERRM: %)', session_id,SQLSTATE,SQLERRM
USING HINT = 'Database error occured (sval cleansess fail)';
END;

BEGIN
v_now := extract(epoch FROM now())::bigint;
select * into strict v_row from app_security.app_val_session_vw where
session_id=p_session_id and session_ip=p_client_ip and
session_user_agent=p_user_agent;
update app_security.app_sessions set session_lastactive=v_now where
session_id=p_session_id;
select row_to_json(v_row) into v_json ;
return v_json;
EXCEPTION
WHEN OTHERS THEN
RAISE NOTICE 'Failed to validate session for session % (SQLSTATE: % -
SQLERRM: %)', p_session_id,SQLSTATE,SQLERRM
USING HINT = 'Database error occured (sval fail)';
return '[false]';
END;

END;
$$ LANGUAGE plpgsql;

--
Adrian Klaver
adrian(dot)klaver(at)aklaver(dot)com

In response to

Responses

Browse pgsql-general by date

  From Date Subject
Next Message litu16 2015-06-26 18:41:15 How to convert a text variable into a timestamp in postgreSQL?
Previous Message Adrian Klaver 2015-06-26 17:52:53 Re: Re: Get the difference between two timestamp cells but in a special format in PostgreSQL