Skip to content

Commit 7965be2

Browse files
authored
add GRANT EXECUTE to SECURITY DEFINER function example; number steps (#19342)
1 parent 359b7a4 commit 7965be2

File tree

2 files changed

+136
-114
lines changed

2 files changed

+136
-114
lines changed

src/current/v24.3/create-function.md

Lines changed: 68 additions & 57 deletions
Original file line numberDiff line numberDiff line change
@@ -294,77 +294,88 @@ The preceding example modifies a given `name` value and returns the `NEW` [trigg
294294

295295
The following example defines a function using the `SECURITY DEFINER` clause. This causes the function to execute with the privileges of the function owner.
296296

297-
Create two roles:
297+
1. Create two roles:
298298

299-
{% include_cached copy-clipboard.html %}
300-
~~~ sql
301-
CREATE ROLE owner;
302-
CREATE ROLE invoker;
303-
~~~
299+
{% include_cached copy-clipboard.html %}
300+
~~~ sql
301+
CREATE ROLE owner;
302+
CREATE ROLE invoker;
303+
~~~
304304

305-
Grant a [`SELECT` privilege]({% link {{ page.version.version }}/grant.md %}#supported-privileges) on the `user_promo_codes` table to the `owner` role.
305+
1. Grant a [`SELECT` privilege]({% link {{ page.version.version }}/grant.md %}#supported-privileges) on the `user_promo_codes` table to the `owner` role.
306306

307-
{% include_cached copy-clipboard.html %}
308-
~~~ sql
309-
GRANT SELECT ON TABLE user_promo_codes TO owner;
310-
~~~
307+
{% include_cached copy-clipboard.html %}
308+
~~~ sql
309+
GRANT SELECT ON TABLE user_promo_codes TO owner;
310+
~~~
311311

312-
Set your role to `owner`.
312+
1. Set your role to `owner`.
313313

314-
{% include_cached copy-clipboard.html %}
315-
~~~ sql
316-
SET ROLE owner;
317-
~~~
318-
319-
Create a simple `SECURITY DEFINER` function that reads the contents of `user_promo_codes`.
314+
{% include_cached copy-clipboard.html %}
315+
~~~ sql
316+
SET ROLE owner;
317+
~~~
320318

321-
{% include_cached copy-clipboard.html %}
322-
~~~ sql
323-
CREATE OR REPLACE FUNCTION get_codes()
324-
RETURNS SETOF RECORD
325-
LANGUAGE SQL
326-
SECURITY DEFINER
327-
AS $$
328-
SELECT * FROM user_promo_codes;
329-
$$;
330-
~~~
319+
1. Create a simple `SECURITY DEFINER` function that reads the contents of `user_promo_codes`.
331320

332-
Set your role to `invoker`.
321+
{% include_cached copy-clipboard.html %}
322+
~~~ sql
323+
CREATE OR REPLACE FUNCTION get_codes()
324+
RETURNS SETOF RECORD
325+
LANGUAGE SQL
326+
SECURITY DEFINER
327+
AS $$
328+
SELECT * FROM user_promo_codes;
329+
$$;
330+
~~~
333331

334-
{% include_cached copy-clipboard.html %}
335-
~~~ sql
336-
SET ROLE invoker;
337-
~~~
332+
1. Grant the [`EXECUTE` privilege]({% link {{ page.version.version }}/grant.md %}#supported-privileges) on the `get_codes` function to the `invoker` role.
338333

339-
`invoker` does not have the privileges to read the `user_promo_codes` table directly:
334+
{% include_cached copy-clipboard.html %}
335+
~~~ sql
336+
GRANT EXECUTE ON FUNCTION get_codes() TO invoker;
337+
~~~
340338

341-
{% include_cached copy-clipboard.html %}
342-
~~~ sql
343-
SELECT * FROM user_promo_codes;
344-
~~~
339+
{{site.data.alerts.callout_info}}
340+
This step is not necessary if the function is defined on the `public` schema, for which roles automatically have the `EXECUTE` privilege.
341+
{{site.data.alerts.end}}
345342

346-
~~~
347-
ERROR: user invoker does not have SELECT privilege on relation user_promo_codes
348-
SQLSTATE: 42501
349-
~~~
343+
1. Set your role to `invoker`.
350344

351-
As `invoker`, you can call the `get_codes` function, since `SECURITY DEFINER` is executed with the privileges of the `owner` role:
345+
{% include_cached copy-clipboard.html %}
346+
~~~ sql
347+
SET ROLE invoker;
348+
~~~
352349

353-
{% include_cached copy-clipboard.html %}
354-
~~~ sql
355-
SELECT get_codes();
356-
~~~
350+
1. `invoker` does not have the privileges to read the `user_promo_codes` table directly:
357351

358-
~~~
359-
get_codes
360-
------------------------------------------------------------------------------------------------------------
361-
("new york",00000000-0000-4000-8000-000000000000,0_audience_thought_seven,"2019-01-02 03:04:05",10)
362-
("new york",051eb851-eb85-4ec0-8000-000000000001,1_assume_its_leg,"2019-01-02 03:04:05.001",0)
363-
("new york",0a3d70a3-d70a-4d80-8000-000000000002,2_popular_if_describe,"2019-01-02 03:04:05.002",16)
364-
("new york",0f5c28f5-c28f-4c00-8000-000000000003,3_environmental_myself_add,"2019-01-02 03:04:05.003",4)
365-
("new york",147ae147-ae14-4b00-8000-000000000004,4_rule_edge_career,"2019-01-02 03:04:05.004",13)
366-
(5 rows)
367-
~~~
352+
{% include_cached copy-clipboard.html %}
353+
~~~ sql
354+
SELECT * FROM user_promo_codes;
355+
~~~
356+
357+
~~~
358+
ERROR: user invoker does not have SELECT privilege on relation user_promo_codes
359+
SQLSTATE: 42501
360+
~~~
361+
362+
1. As `invoker`, call the `get_codes` function to read `user_promo_codes`, since `SECURITY DEFINER` is executed with the privileges of the `owner` role (i.e., `SELECT` on `user_promo_codes`).
363+
364+
{% include_cached copy-clipboard.html %}
365+
~~~ sql
366+
SELECT get_codes();
367+
~~~
368+
369+
~~~
370+
get_codes
371+
------------------------------------------------------------------------------------------------------------
372+
("new york",00000000-0000-4000-8000-000000000000,0_audience_thought_seven,"2019-01-02 03:04:05",10)
373+
("new york",051eb851-eb85-4ec0-8000-000000000001,1_assume_its_leg,"2019-01-02 03:04:05.001",0)
374+
("new york",0a3d70a3-d70a-4d80-8000-000000000002,2_popular_if_describe,"2019-01-02 03:04:05.002",16)
375+
("new york",0f5c28f5-c28f-4c00-8000-000000000003,3_environmental_myself_add,"2019-01-02 03:04:05.003",4)
376+
("new york",147ae147-ae14-4b00-8000-000000000004,4_rule_edge_career,"2019-01-02 03:04:05.004",13)
377+
(5 rows)
378+
~~~
368379

369380
## See also
370381

src/current/v25.1/create-function.md

Lines changed: 68 additions & 57 deletions
Original file line numberDiff line numberDiff line change
@@ -294,77 +294,88 @@ The preceding example modifies a given `name` value and returns the `NEW` [trigg
294294

295295
The following example defines a function using the `SECURITY DEFINER` clause. This causes the function to execute with the privileges of the function owner.
296296

297-
Create two roles:
297+
1. Create two roles:
298298

299-
{% include_cached copy-clipboard.html %}
300-
~~~ sql
301-
CREATE ROLE owner;
302-
CREATE ROLE invoker;
303-
~~~
299+
{% include_cached copy-clipboard.html %}
300+
~~~ sql
301+
CREATE ROLE owner;
302+
CREATE ROLE invoker;
303+
~~~
304304

305-
Grant a [`SELECT` privilege]({% link {{ page.version.version }}/grant.md %}#supported-privileges) on the `user_promo_codes` table to the `owner` role.
305+
1. Grant a [`SELECT` privilege]({% link {{ page.version.version }}/grant.md %}#supported-privileges) on the `user_promo_codes` table to the `owner` role.
306306

307-
{% include_cached copy-clipboard.html %}
308-
~~~ sql
309-
GRANT SELECT ON TABLE user_promo_codes TO owner;
310-
~~~
307+
{% include_cached copy-clipboard.html %}
308+
~~~ sql
309+
GRANT SELECT ON TABLE user_promo_codes TO owner;
310+
~~~
311311

312-
Set your role to `owner`.
312+
1. Set your role to `owner`.
313313

314-
{% include_cached copy-clipboard.html %}
315-
~~~ sql
316-
SET ROLE owner;
317-
~~~
318-
319-
Create a simple `SECURITY DEFINER` function that reads the contents of `user_promo_codes`.
314+
{% include_cached copy-clipboard.html %}
315+
~~~ sql
316+
SET ROLE owner;
317+
~~~
320318

321-
{% include_cached copy-clipboard.html %}
322-
~~~ sql
323-
CREATE OR REPLACE FUNCTION get_codes()
324-
RETURNS SETOF RECORD
325-
LANGUAGE SQL
326-
SECURITY DEFINER
327-
AS $$
328-
SELECT * FROM user_promo_codes;
329-
$$;
330-
~~~
319+
1. Create a simple `SECURITY DEFINER` function that reads the contents of `user_promo_codes`.
331320

332-
Set your role to `invoker`.
321+
{% include_cached copy-clipboard.html %}
322+
~~~ sql
323+
CREATE OR REPLACE FUNCTION get_codes()
324+
RETURNS SETOF RECORD
325+
LANGUAGE SQL
326+
SECURITY DEFINER
327+
AS $$
328+
SELECT * FROM user_promo_codes;
329+
$$;
330+
~~~
333331

334-
{% include_cached copy-clipboard.html %}
335-
~~~ sql
336-
SET ROLE invoker;
337-
~~~
332+
1. Grant the [`EXECUTE` privilege]({% link {{ page.version.version }}/grant.md %}#supported-privileges) on the `get_codes` function to the `invoker` role.
338333

339-
`invoker` does not have the privileges to read the `user_promo_codes` table directly:
334+
{% include_cached copy-clipboard.html %}
335+
~~~ sql
336+
GRANT EXECUTE ON FUNCTION get_codes() TO invoker;
337+
~~~
340338

341-
{% include_cached copy-clipboard.html %}
342-
~~~ sql
343-
SELECT * FROM user_promo_codes;
344-
~~~
339+
{{site.data.alerts.callout_info}}
340+
This step is not necessary if the function is defined on the `public` schema, for which roles automatically have the `EXECUTE` privilege.
341+
{{site.data.alerts.end}}
345342

346-
~~~
347-
ERROR: user invoker does not have SELECT privilege on relation user_promo_codes
348-
SQLSTATE: 42501
349-
~~~
343+
1. Set your role to `invoker`.
350344

351-
As `invoker`, you can call the `get_codes` function, since `SECURITY DEFINER` is executed with the privileges of the `owner` role:
345+
{% include_cached copy-clipboard.html %}
346+
~~~ sql
347+
SET ROLE invoker;
348+
~~~
352349

353-
{% include_cached copy-clipboard.html %}
354-
~~~ sql
355-
SELECT get_codes();
356-
~~~
350+
1. `invoker` does not have the privileges to read the `user_promo_codes` table directly:
357351

358-
~~~
359-
get_codes
360-
------------------------------------------------------------------------------------------------------------
361-
("new york",00000000-0000-4000-8000-000000000000,0_audience_thought_seven,"2019-01-02 03:04:05",10)
362-
("new york",051eb851-eb85-4ec0-8000-000000000001,1_assume_its_leg,"2019-01-02 03:04:05.001",0)
363-
("new york",0a3d70a3-d70a-4d80-8000-000000000002,2_popular_if_describe,"2019-01-02 03:04:05.002",16)
364-
("new york",0f5c28f5-c28f-4c00-8000-000000000003,3_environmental_myself_add,"2019-01-02 03:04:05.003",4)
365-
("new york",147ae147-ae14-4b00-8000-000000000004,4_rule_edge_career,"2019-01-02 03:04:05.004",13)
366-
(5 rows)
367-
~~~
352+
{% include_cached copy-clipboard.html %}
353+
~~~ sql
354+
SELECT * FROM user_promo_codes;
355+
~~~
356+
357+
~~~
358+
ERROR: user invoker does not have SELECT privilege on relation user_promo_codes
359+
SQLSTATE: 42501
360+
~~~
361+
362+
1. As `invoker`, call the `get_codes` function to read `user_promo_codes`, since `SECURITY DEFINER` is executed with the privileges of the `owner` role (i.e., `SELECT` on `user_promo_codes`).
363+
364+
{% include_cached copy-clipboard.html %}
365+
~~~ sql
366+
SELECT get_codes();
367+
~~~
368+
369+
~~~
370+
get_codes
371+
------------------------------------------------------------------------------------------------------------
372+
("new york",00000000-0000-4000-8000-000000000000,0_audience_thought_seven,"2019-01-02 03:04:05",10)
373+
("new york",051eb851-eb85-4ec0-8000-000000000001,1_assume_its_leg,"2019-01-02 03:04:05.001",0)
374+
("new york",0a3d70a3-d70a-4d80-8000-000000000002,2_popular_if_describe,"2019-01-02 03:04:05.002",16)
375+
("new york",0f5c28f5-c28f-4c00-8000-000000000003,3_environmental_myself_add,"2019-01-02 03:04:05.003",4)
376+
("new york",147ae147-ae14-4b00-8000-000000000004,4_rule_edge_career,"2019-01-02 03:04:05.004",13)
377+
(5 rows)
378+
~~~
368379

369380
## See also
370381

0 commit comments

Comments
 (0)