Change find_user_role’s and login’s volatility to stable

According to PostgreSQL’s manual[0]:

  “STABLE indicates that the function cannot modify the database, and
   that within a single table scan it will consistently return the same
   result for the same argument values, but that its result could change
   across SQL statements.”

This definition matches both functions.  Moreover, find_user_role did
not need to be written in plpgsql, that i assume—but did not test—are
slower than sql functions.

[0]: https://www.postgresql.org/docs/14/sql-createfunction.html
This commit is contained in:
jordi fita mas 2023-01-16 10:02:31 +01:00
parent 0efd48c40d
commit b63f7e7c54
4 changed files with 6 additions and 11 deletions

View File

@ -10,19 +10,13 @@ set search_path to auth, numerus, public;
create or replace function find_user_role(email email, password text) returns name create or replace function find_user_role(email email, password text) returns name
as as
$$ $$
declare
found_role name;
begin
select role select role
into found_role
from auth."user" from auth."user"
where "user".email = find_user_role.email where "user".email = find_user_role.email
and "user".password = crypt(find_user_role.password, "user".password); and "user".password = crypt(find_user_role.password, "user".password);
return found_role;
end;
$$ $$
language plpgsql; language sql
stable;
comment on function find_user_role(email, text) is comment on function find_user_role(email, text) is
'Return the database role assigned to the user with the given email and password'; 'Return the database role assigned to the user with the given email and password';

View File

@ -22,6 +22,7 @@ begin
end; end;
$$ $$
language plpgsql language plpgsql
stable
security definer; security definer;
comment on function login(email, text) is comment on function login(email, text) is

View File

@ -10,10 +10,10 @@ select plan(12);
set search_path to auth, numerus, public; set search_path to auth, numerus, public;
select has_function('find_user_role'); select has_function('find_user_role');
select function_lang_is('find_user_role', array ['email', 'text'], 'plpgsql'); select function_lang_is('find_user_role', array ['email', 'text'], 'sql');
select function_returns('find_user_role', array ['email', 'text'], 'name'); select function_returns('find_user_role', array ['email', 'text'], 'name');
select isnt_definer('find_user_role', array ['email', 'text']); select isnt_definer('find_user_role', array ['email', 'text']);
select volatility_is('find_user_role', array ['email', 'text'], 'volatile'); select volatility_is('find_user_role', array ['email', 'text'], 'stable');
select function_privs_are('find_user_role', array ['email', 'text'], 'guest', array []::text[]); select function_privs_are('find_user_role', array ['email', 'text'], 'guest', array []::text[]);
select function_privs_are('find_user_role', array ['email', 'text'], 'invoicer', array []::text[]); select function_privs_are('find_user_role', array ['email', 'text'], 'invoicer', array []::text[]);
select function_privs_are('find_user_role', array ['email', 'text'], 'admin', array []::text[]); select function_privs_are('find_user_role', array ['email', 'text'], 'admin', array []::text[]);

View File

@ -13,7 +13,7 @@ select has_function('login');
select function_lang_is('login', array ['email', 'text'], 'plpgsql'); select function_lang_is('login', array ['email', 'text'], 'plpgsql');
select function_returns('login', array ['email', 'text'], 'name'); select function_returns('login', array ['email', 'text'], 'name');
select is_definer('login', array ['email', 'text']); select is_definer('login', array ['email', 'text']);
select volatility_is('login', array ['email', 'text'], 'volatile'); select volatility_is('login', array ['email', 'text'], 'stable');
select function_privs_are('login', array ['email', 'text'], 'guest', array ['EXECUTE']); select function_privs_are('login', array ['email', 'text'], 'guest', array ['EXECUTE']);
select function_privs_are('login', array ['email', 'text'], 'invoicer', array []::text[]); select function_privs_are('login', array ['email', 'text'], 'invoicer', array []::text[]);
select function_privs_are('login', array ['email', 'text'], 'admin', array []::text[]); select function_privs_are('login', array ['email', 'text'], 'admin', array []::text[]);