Secure and control access to application data using parameterized secure views
Stay organized with collections
Save and categorize content based on your preferences.
This tutorial describes how to use parameterized secure views in
AlloyDB for PostgreSQL to restrict user access to parameterized views using
AlloyDB Studio or psql.
Examples are included to illustrate the capabilities of parameterized secure
views. These examples are intended for demonstration purposes only.
Objectives
Create secure parameterized views with named view parameters.
Create the database role that is used by the application to connect to the
database and access parameterized secure views.
Grant the new role permissions to the secure views and revoke access to the
base tables.
Connect using the new role and verify that the restricted tables can't be
accessed.
Run queries on the parameterized secure view using the
execute_parameterized_query function.
Costs
In this document, you use the following billable components of Google Cloud:
To generate a cost estimate based on your projected usage,
use the pricing calculator.
New Google Cloud users might be eligible for a free trial.
When you finish the tasks that are described in this document, you can avoid
continued billing by deleting the resources that you created. For more information, see
Clean up.
To prepare for running queries on a parameterized secure view, you must first
set up parameterized views, the database and database roles, the
parameterized_view extension, and the application schema.
Set up parameterized views and the database
Request the AlloyDB team to enable the
parameterized_views.enabled database flag, which loads the required extension
libraries.
Create a database called database for the application data and
parameterized views. For more information, see Create a database.
Create database roles, the extension, and the application schema
Create the parameterized_views extension in the database.
-- Requires parameterized_views.enabled set to trueCREATEEXTENSIONparameterized_views;
When the extension is created, the system also creates a schema named
parameterized_views so that the APIs are contained in that schema's
namespace and so that those APIs don't conflict with existing APIs.
Create the AlloyDB administrative role, which
owns and manages the database.
Create a new database role for executing queries against parameterized secure
views. This is an AlloyDB role that the application
uses to connect and sign into the database to execute queries with
limited access to public functions or objects to the minimal required set.
CREATETABLEschema.checked_items(bag_idINT,timestampTIMESTAMP,loc_codeCHAR(3),scan_typeCHAR(1),locationTEXT,customer_idINT);INSERTINTOschema.checked_items(bag_id,timestamp,loc_code,scan_type,location,customer_id)VALUES(101,'2023-10-26 10:00:00','ABC','I','Warehouse A',123),(102,'2023-10-26 10:15:30','DEF','O','Loading Dock B',456),(103,'2023-10-26 10:30:45','GHI','I','Conveyor Belt 1',789),(104,'2023-10-26 11:00:00','JKL','O','Shipping Area C',101),(105,'2023-10-26 11:45:15','MNO','I','Sorting Station D',202),(106,'2023-10-26 12:00:00','PQR','O','Truck Bay E',303);
Create secure parameterized views and set up access privileges
To create secure parameterized views and to set up appropriate access privileges
for the base table and views, follow these steps:
To verify that the parameterized secure views are restricting access to the
designated views, run the following commands as psv_user. This is a
AlloyDB database role that the application uses to connect and
sign into the database to execute queries.
Access the parameterized secure view using the execute_parameterized_query
function:
SELECT*FROMparameterized_views.execute_parameterized_query(query=>'SELECT * from schema.secure_checked_items',param_names=>ARRAY['app_end_userid'],param_values=>ARRAY['303']);
To improve security for natural language generated queries, integrate your
parameterized secure views using AlloyDB AI natural language.
Clean up
To avoid incurring charges to your Google Cloud account for the resources used in this
tutorial, either delete the project that contains the resources, or keep the project and
delete the individual resources.
In the Google Cloud console, go to the Clusters page.
[[["Easy to understand","easyToUnderstand","thumb-up"],["Solved my problem","solvedMyProblem","thumb-up"],["Other","otherUp","thumb-up"]],[["Hard to understand","hardToUnderstand","thumb-down"],["Incorrect information or sample code","incorrectInformationOrSampleCode","thumb-down"],["Missing the information/samples I need","missingTheInformationSamplesINeed","thumb-down"],["Other","otherDown","thumb-down"]],["Last updated 2025-08-26 UTC."],[],[],null,["*** ** * ** ***\n\n|\n| **Preview**\n|\n|\n| This feature is subject to the \"Pre-GA Offerings Terms\" in the General Service Terms section\n| of the [Service Specific Terms](/terms/service-terms#1).\n|\n| Pre-GA features are available \"as is\" and might have limited support.\n|\n| For more information, see the\n| [launch stage descriptions](/products#product-launch-stages).\n|\n|\n| For information about access to this\n| release, see the\n| [access request page](https://docs.google.com/forms/d/16wliam2vok6sdBjYwJIgWV4hw7MW9x5iQ29UwPAKqB0/viewform).\n\nThis tutorial describes how to use parameterized secure views in\nAlloyDB for PostgreSQL to restrict user access to parameterized views using\nAlloyDB Studio or psql.\nExamples are included to illustrate the capabilities of parameterized secure\nviews. These examples are intended for demonstration purposes only.\n\nObjectives\n\n- Create secure parameterized views with named view parameters.\n- Create the database role that is used by the application to connect to the database and access parameterized secure views.\n- Grant the new role permissions to the secure views and revoke access to the base tables.\n- Connect using the new role and verify that the restricted tables can't be accessed.\n- Run queries on the parameterized secure view using the `execute_parameterized_query` function.\n\nCosts\n\n\nIn this document, you use the following billable components of Google Cloud:\n\n\n- [AlloyDB for PostgreSQL](/alloydb/pricing)\n\n\nTo generate a cost estimate based on your projected usage,\nuse the [pricing calculator](/products/calculator). \nNew Google Cloud users might be eligible for a [free trial](/free). \n\n\u003cbr /\u003e\n\nWhen you finish the tasks that are described in this document, you can avoid\ncontinued billing by deleting the resources that you created. For more information, see\n[Clean up](#clean-up).\n\nBefore you begin\n\nRequest access\n\nBefore you can use parameterized secure views, you must [request access to AlloyDB parameterized secure views](https://docs.google.com/forms/d/e/1FAIpQLSdbW1DeZK5ei_8eYjqXLbC9freKIZsZ4J3USluXrgyl56h95w/viewform)\nand wait until you receive the enablement confirmation before you begin.\n\nEnable billing and required APIs\n\n1. In the Google Cloud console, select a project.\n\n [Go to project selector](https://console.cloud.google.com/projectselector2/home/dashboard)\n2. [Make sure that billing is enabled for your Google Cloud project.](/billing/docs/how-to/verify-billing-enabled#confirm_billing_is_enabled_on_a_project)\n\n3. Enable the Cloud APIs necessary to create and connect to AlloyDB for PostgreSQL.\n\n [Enable\n the API](https://console.cloud.google.com/flows/enableapi?apiid=alloydb.googleapis.com)\n 1. In the **Confirm project** step, click **Next** to confirm the name of the project you are going to make changes to.\n 2. In the **Enable APIs** step, click **Enable** to enable the following:\n\n - AlloyDB API\n\nCreate and connect to a database\n\n1. [Create a cluster and its primary instance](/alloydb/docs/quickstart/create-and-connect#create-cluster).\n2. [Connect to your instance and create a database](/alloydb/docs/quickstart/create-and-connect#run). \n\nPrepare your environment\n\nTo prepare for running queries on a parameterized secure view, you must first\nset up parameterized views, the database and database roles, the\n`parameterized_view` extension, and the application schema.\n\nSet up parameterized views and the database\n\n1. Request the AlloyDB team to enable the\n `parameterized_views.enabled database` flag, which loads the required extension\n libraries.\n\n2. Create a database called `database` for the application data and\n parameterized views. For more information, see [Create a database](/alloydb/docs/database-create).\n\nCreate database roles, the extension, and the application schema\n\n1. Using [AlloyDB Studio](/alloydb/docs/manage-data-using-studio)\n or [psql](/alloydb/docs/connect-psql), connect to the database as the\n `postgres` user or as a user with [AlloyDB superuser](/alloydb/docs/database-users/overview#alloydbsuperuser)\n privileges.\n\n psql database -U postgres\n\n For more information, see [About database user management in AlloyDB](/alloydb/docs/database-users/overview).\n2. Create the `parameterized_views` extension in the database.\n\n -- Requires parameterized_views.enabled set to true\n CREATE EXTENSION parameterized_views;\n\n When the extension is created, the system also creates a schema named\n `parameterized_views` so that the APIs are contained in that schema's\n namespace and so that those APIs don't conflict with existing APIs.\n | **Note:** You must create an extension in every database in which parameterized views are created.\n3. Create the AlloyDB administrative role, which\n owns and manages the database.\n\n CREATE ROLE admin_user WITH LOGIN PASSWORD '...';\n GRANT ALL PRIVILEGES ON DATABASE database TO admin_user;\n\n For more information, see\n [`CREATE USER`](https://www.postgresql.org/docs/15/sql-createuser.html).\n4. Create a new database role for executing queries against parameterized secure\n views. This is an AlloyDB role that the application\n uses to connect and sign into the database to execute queries with\n limited access to public functions or objects to the minimal required set.\n\n CREATE ROLE psv_user WITH LOGIN PASSWORD '...';\n\n For more information, see [`CREATE USER`](https://www.postgresql.org/docs/15/sql-createuser.html).\n5. Connect as the administrative user.\n\n SET role TO admin_user;\n\n6. Create the schema that contains the tables.\n\n CREATE SCHEMA schema;\n\n7. Create the tables and insert data.\n\n CREATE TABLE schema.checked_items(bag_id INT,timestamp TIMESTAMP, loc_code CHAR(3), scan_type CHAR(1), location TEXT, customer_id INT);\n\n INSERT INTO schema.checked_items (bag_id, timestamp, loc_code, scan_type, location, customer_id) VALUES\n (101, '2023-10-26 10:00:00', 'ABC', 'I', 'Warehouse A', 123),\n (102, '2023-10-26 10:15:30', 'DEF', 'O', 'Loading Dock B', 456),\n (103, '2023-10-26 10:30:45', 'GHI', 'I', 'Conveyor Belt 1', 789),\n (104, '2023-10-26 11:00:00', 'JKL', 'O', 'Shipping Area C', 101),\n (105, '2023-10-26 11:45:15', 'MNO', 'I', 'Sorting Station D', 202),\n (106, '2023-10-26 12:00:00', 'PQR', 'O', 'Truck Bay E', 303);\n\nCreate secure parameterized views and set up access privileges\n\nTo create secure parameterized views and to set up appropriate access privileges\nfor the base table and views, follow these steps:\n\n1. Using [AlloyDB Studio](/alloydb/docs/manage-data-using-studio)\n or [psql](/alloydb/docs/connect-psql), connect to the database as `admin_user`.\n\n psql database -U admin_user\n\n2. To provide limited access to the view, create a parameterized secure view:\n\n CREATE VIEW schema.secure_checked_items WITH (security_barrier) AS\n SELECT bag_id, timestamp, location\n FROM schema.checked_items t\n WHERE customer_id = $@app_end_userid;\n\n3. Grant access to the view.\n\n GRANT SELECT ON schema.secure_checked_items TO psv_user;\n\n4. To access the view, grant access to the schema.\n\n GRANT USAGE ON SCHEMA schema TO psv_user;\n\n5. Revoke direct access to the base table.\n\n REVOKE ALL PRIVILEGES ON schema.checked_items FROM psv_user;\n\nVerify data security\n\nTo verify that the parameterized secure views are restricting access to the\ndesignated views, run the following commands as `psv_user`. This is a\nAlloyDB database role that the application uses to connect and\nsign into the database to execute queries.\n\n1. Connect as a parameterized secure views user.\n\n psql database -U psv_user\n\n2. Verify that the base table can't be accessed.\n\n SELECT * FROM schema.checked_items;\n ERROR: permission denied for table checked_items\n\n3. Access the parameterized secure view using the `execute_parameterized_query`\n function:\n\n SELECT * FROM parameterized_views.execute_parameterized_query(\n query =\u003e 'SELECT * from schema.secure_checked_items',\n param_names =\u003e ARRAY ['app_end_userid'],\n param_values =\u003e ARRAY ['303']\n );\n\n4. To improve security for natural language generated queries, integrate your\n parameterized secure views using [AlloyDB AI natural language](/alloydb/docs/ai/generate-sql-queries-natural-language).\n\nClean up\n\n\nTo avoid incurring charges to your Google Cloud account for the resources used in this\ntutorial, either delete the project that contains the resources, or keep the project and\ndelete the individual resources.\n\n1. In the Google Cloud console, go to the **Clusters** page.\n\n [Go to Clusters](https://console.cloud.google.com/alloydb/clusters)\n2. Click the name of your cluster, `my-cluster`, in the **Resource name**\n column.\n\n3. Click *delete* **Delete cluster**.\n\n4. In **Delete cluster my-cluster** , enter `my-cluster` to confirm you want to\n delete your cluster.\n\n5. Click **Delete**.\n\n6. If you created a private connection when you\n [created a cluster](#create-and-connect-to-database), go to the Google Cloud console\n [Networking page](https://console.cloud.google.com/networking/networks/details/default)\n and click **Delete VPC network**.\n\n7. Using [AlloyDB Studio](/alloydb/docs/manage-data-using-studio)\n or [psql](/alloydb/docs/connect-psql), connect to the database as `postgres`.\n\n psql database -U postgres\n\n8. Drop the objects that you created.\n\n DROP VIEW schema.secure_checked_items;\n DROP TABLE schema.checked_items;\n DROP SCHEMA schema;\n DROP ROLE psv_user;\n DROP ROLE admin_user;\n DROP EXTENSION parameterized_views;\n\nWhat's next\n\n- Learn about [parameterized secure views](/alloydb/docs/parameterized-secure-views-overview).\n- Learn how to [manage application data security using parameterized secure views](/alloydb/docs/manage-application-data-security-parameterized-secure-views)."]]