Re: How to ensure that a stored function always returns TRUE or FALSE?

From: Merlin Moncure <mmoncure(at)gmail(dot)com>
To: Alexander Farber <alexander(dot)farber(at)gmail(dot)com>
Cc: pgsql-general <pgsql-general(at)postgresql(dot)org>
Subject: Re: How to ensure that a stored function always returns TRUE or FALSE?
Date: 2016-03-02 14:54:01
Message-ID: CAHyXU0xdFQ--0aTm3Md7d1x5ZnfBJDe0eMJHnVtCZdBJuFDqew@mail.gmail.com
Views: Raw Message | Whole Thread | Download mbox | Resend email
Thread:
Lists: pgsql-general

On Wed, Mar 2, 2016 at 3:45 AM, Alexander Farber
<alexander(dot)farber(at)gmail(dot)com> wrote:
> Good morning,
>
> with the following stored function I would like to validate user data:
>
> CREATE OR REPLACE FUNCTION check_user(
> in_social integer,
> in_sid varchar(255),
> in_auth varchar(32))
> RETURNS boolean AS
> $func$
> SELECT MD5('secret word' || in_social || in_sid) = in_auth;
> $func$ LANGUAGE sql IMMUTABLE;
>
> I am going to call it while looping through a JSON array of objects in
> another stored functions - and will RAISE EXCEPTION if it returns FALSE for
> any of the JSON objects (and thus rollback the whole transaction).

Personally I would write the check like this:
SELECT MD5('secret word' || in_social || in_sid) IS NOT DISTINCT FROM in_auth;

...for better handling of NULLS within the input arguments. It is
definitely write for this function to be sql, not plpgsql, because it
is a good candidate for inlining.

Also, I tend to wrap RAISE NOTICE with a function:

CREATE OR REPLACE FUNCTION Notice(TEXT) RETURNS VOID AS
$$
BEGIN
RAISE NOTICE '%', $1;
END;
$$ LANGUAGE PLPGSQL;

CREATE OR REPLACE FUNCTION Exception(TEXT) RETURNS VOID AS
$$
BEGIN
RAISE NOTICE '%', $1;
END;
$$ LANGUAGE PLPGSQL;

CREATE OR REPLACE FUNCTION NoticeValue(anyelement) RETURNS anyelement AS
$$
SELECT $1 FROM (SELECT NOTICE($1::TEXT)) q;
$$ LANGUAGE SQL IMMUTABLE;

Then you can write a checker function like this:

CREATE OR REPLACE FUNCTION test4() RETURNS void AS
$func$
BEGIN
PERFORM Exception('invalid user') WHERE NOT
check_user(42, 'user1', NULL);
END
$func$ LANGUAGE plpgsql;

"NoticeValue()" Is a wonderful debugging tool for pl/pgsql. It allows
you to quickly virtually anything in a query without rewriting the
entire query.

SELECT NoticeValue(foo) FROM bar;

merlin

In response to

Browse pgsql-general by date

  From Date Subject
Next Message Vitaly Burovoy 2016-03-02 15:55:36 Re: How to ensure that a stored function always returns TRUE or FALSE?
Previous Message Johnny Morano 2016-03-02 14:38:54 Re: bloated postgres data folder, clean up