Loading content...
Authentication answers the question 'Who are you?' But knowing someone's identity tells us nothing about what they should be allowed to do. Authorization is the security mechanism that bridges this gap—it's the system that transforms identity into permission.
In enterprise database environments, authorization is deceptively complex. A single database might serve hundreds of applications, thousands of users, and millions of rows of data—each with different sensitivity levels, regulatory requirements, and access patterns. The authorization system must efficiently evaluate permissions for every single query, often making thousands of decisions per second.
This isn't just about security—poorly designed authorization creates operational nightmares: support tickets for access requests, audit failures, compliance violations, and the constant pressure to grant 'just a little more access' until everyone has administrative privileges.
By the end of this page, you will understand the fundamental models of database authorization (DAC, MAC, RBAC), master SQL GRANT/REVOKE semantics across major database platforms, implement role-based access control architectures, leverage row-level security for fine-grained data protection, and apply the principle of least privilege systematically.
Authorization determines what actions an authenticated entity (user, role, or service) may perform on database objects. Unlike authentication, which is typically a one-time verification at connection establishment, authorization decisions occur continuously throughout a session—every SELECT, INSERT, UPDATE, DELETE, and DDL statement is validated against the authorization system.
Core Authorization Concepts:
Authorization Models:
Database systems implement various authorization models, each with distinct characteristics:
| Model | Description | Control | Use Case |
|---|---|---|---|
| Discretionary Access Control (DAC) | Object owners grant permissions at their discretion | Decentralized, owner-controlled | Most SQL databases (default) |
| Mandatory Access Control (MAC) | System-enforced labels and clearance levels | Centralized, policy-driven | Government, military systems (Oracle Label Security) |
| Role-Based Access Control (RBAC) | Permissions assigned to roles, roles assigned to users | Centralized, scalable | Enterprise applications (standard practice) |
| Attribute-Based Access Control (ABAC) | Dynamic decisions based on attributes (time, location, etc.) | Fine-grained, context-aware | Cloud platforms, modern IAM |
Discretionary Access Control (DAC) in SQL:
The SQL standard defines a DAC model where object owners control access to their objects. When a user creates a table, they become its owner and can grant privileges to others. This model is implemented by all major relational databases:
Pure DAC systems suffer from the 'Trojan Horse' problem. If malicious code executes with an authorized user's privileges, it can access or copy all data that user can access, then grant access to an attacker's account. This is why enterprise environments layer RBAC and MAC on top of DAC.
SQL defines a comprehensive privilege system through the GRANT and REVOKE statements. Understanding these statements deeply is essential for database security administration.
Privilege Types:
SQL defines privileges at multiple granularity levels:
| Level | Privileges | Description |
|---|---|---|
| Database | CREATE, CONNECT, TEMPORARY | Control database-wide operations |
| Schema | USAGE, CREATE, ALTER, DROP | Control schema access and modification |
| Table | SELECT, INSERT, UPDATE, DELETE, TRUNCATE, REFERENCES, TRIGGER | Control table data operations |
| Column | SELECT, INSERT, UPDATE, REFERENCES | Fine-grained column access |
| Sequence | USAGE, SELECT, UPDATE | Control sequence operations |
| Function/Procedure | EXECUTE | Control function execution |
| Type | USAGE | Control use of custom types |
123456789101112131415161718192021222324252627282930313233343536373839404142434445464748495051525354555657585960616263646566676869707172
-- ================================================-- GRANT Statement Fundamentals-- ================================================ -- Basic table privilege grantGRANT SELECT ON employees TO hr_analyst; -- Grant multiple privilegesGRANT SELECT, INSERT, UPDATE ON employees TO hr_manager; -- Grant all privileges (not recommended - violates least privilege)GRANT ALL PRIVILEGES ON employees TO hr_admin; -- Grant with ability to re-grant (dangerous - creates privilege chains)GRANT SELECT ON employees TO senior_hr WITH GRANT OPTION; -- Grant to all users (PUBLIC pseudo-role)GRANT SELECT ON public_announcements TO PUBLIC; -- Column-level grants (fine-grained access)GRANT SELECT (employee_id, name, department) ON employees TO auditor;-- auditor cannot see salary, ssn, or other sensitive columns -- Grant on all tables in schemaGRANT SELECT ON ALL TABLES IN SCHEMA reporting TO report_reader; -- Grant on future tables (PostgreSQL)ALTER DEFAULT PRIVILEGES IN SCHEMA reporting GRANT SELECT ON TABLES TO report_reader; -- ================================================-- REVOKE Statement Fundamentals-- ================================================ -- Basic revokeREVOKE INSERT ON employees FROM hr_analyst; -- Revoke all privilegesREVOKE ALL PRIVILEGES ON employees FROM former_employee; -- Revoke grant option only (user keeps the privilege)REVOKE GRANT OPTION FOR SELECT ON employees FROM senior_hr; -- Cascade revoke (revoke from grantees of this grantee)REVOKE SELECT ON employees FROM senior_hr CASCADE; -- Restrict revoke (fail if others depend on this grant)REVOKE SELECT ON employees FROM senior_hr RESTRICT; -- ================================================-- Viewing Current Privileges-- ================================================ -- PostgreSQL: View table privilegesSELECT grantee, table_schema, table_name, privilege_type, is_grantableFROM information_schema.table_privilegesWHERE table_name = 'employees'; -- PostgreSQL: View role membershipsSELECT r.rolname AS role, m.rolname AS member, g.rolname AS granted_byFROM pg_auth_members amJOIN pg_roles r ON r.oid = am.roleidJOIN pg_roles m ON m.oid = am.memberJOIN pg_roles g ON g.oid = am.grantor;REVOKE removes a previously granted permission (returns to default state). DENY explicitly prohibits access, overriding any GRANT. In SQL Server, DENY takes precedence—if a user has both GRANT and DENY, the DENY wins. Use DENY sparingly for explicit exclusions; prefer REVOKE for routine permission removal.
Role-Based Access Control is the cornerstone of scalable database authorization. Instead of granting privileges directly to users, permissions are granted to roles, and roles are assigned to users. This indirection provides enormous administrative and security benefits.
Why RBAC?
Consider an organization with 500 employees accessing a database with 200 tables. Without roles:
With RBAC:
1234567891011121314151617181920212223242526272829303132333435363738394041424344454647484950515253545556575859606162636465
-- ================================================-- Complete RBAC Implementation in PostgreSQL-- ================================================ -- Step 1: Create functional roles (no login capability)CREATE ROLE hr_read NOLOGIN;CREATE ROLE hr_write NOLOGIN;CREATE ROLE finance_read NOLOGIN;CREATE ROLE finance_write NOLOGIN;CREATE ROLE audit_read NOLOGIN; -- Step 2: Establish role hierarchy -- hr_write inherits from hr_read (writers can also read)GRANT hr_read TO hr_write; -- finance_write inherits from finance_readGRANT finance_read TO finance_write; -- auditors get read access to everythingGRANT hr_read TO audit_read;GRANT finance_read TO audit_read; -- Step 3: Grant object privileges to rolesGRANT USAGE ON SCHEMA hr TO hr_read, hr_write;GRANT SELECT ON ALL TABLES IN SCHEMA hr TO hr_read;GRANT INSERT, UPDATE, DELETE ON ALL TABLES IN SCHEMA hr TO hr_write; GRANT USAGE ON SCHEMA finance TO finance_read, finance_write;GRANT SELECT ON ALL TABLES IN SCHEMA finance TO finance_read;GRANT INSERT, UPDATE, DELETE ON ALL TABLES IN SCHEMA finance TO finance_write; -- Auditors need read on audit logGRANT USAGE ON SCHEMA audit TO audit_read;GRANT SELECT ON audit.audit_log TO audit_read; -- Step 4: Handle future objects (critical for maintainability!)ALTER DEFAULT PRIVILEGES IN SCHEMA hr GRANT SELECT ON TABLES TO hr_read;ALTER DEFAULT PRIVILEGES IN SCHEMA hr GRANT INSERT, UPDATE, DELETE ON TABLES TO hr_write; -- Step 5: Create login roles (actual users)CREATE ROLE alice LOGIN PASSWORD 'secure_password_1';CREATE ROLE bob LOGIN PASSWORD 'secure_password_2';CREATE ROLE carol LOGIN PASSWORD 'secure_password_3';CREATE ROLE david LOGIN PASSWORD 'secure_password_4'; -- Step 6: Assign roles to usersGRANT hr_write TO alice; -- HR Manager: read + writeGRANT hr_read TO bob; -- HR Analyst: read onlyGRANT finance_write TO carol; -- Finance Manager: read + writeGRANT audit_read TO david; -- Auditor: read everything -- Step 7: Set role activation (optional - require explicit SET ROLE)ALTER ROLE alice SET role = 'hr_write'; -- Default active role -- View role membershipsSELECT r.rolname AS role, ARRAY_AGG(m.rolname) AS membersFROM pg_roles rJOIN pg_auth_members am ON r.oid = am.roleidJOIN pg_roles m ON m.oid = am.memberGROUP BY r.rolname;Design roles around job functions, not individuals or departments. Create granular roles (reader, writer, admin) and compose them as needed. Avoid creating roles like 'john_smith_access' or 'temporary_project_role'. Good role names are self-documenting: 'order_processor_read', 'inventory_update', 'reporting_analyst'.
Traditional SQL privileges operate at the object level—you either have access to a table or you don't. But many applications require finer granularity: a sales representative should see only their own customer records, a regional manager should see only their region's data, a tenant in a multi-tenant SaaS should see only their organization's data.
Row-Level Security (RLS) provides this capability by automatically filtering rows based on security policies. When a user queries a table, only rows matching their policy predicates are visible—and this filtering is transparent and cannot be bypassed.
RLS Use Cases:
1234567891011121314151617181920212223242526272829303132333435363738394041424344454647484950515253545556575859606162636465666768697071727374757677787980
-- ================================================-- PostgreSQL Row-Level Security Implementation-- ================================================ -- Scenario: Multi-tenant SaaS application-- Each row has tenant_id; users should only see their tenant's data -- Step 1: Create table with tenant columnCREATE TABLE orders ( order_id SERIAL PRIMARY KEY, tenant_id INTEGER NOT NULL, customer_name TEXT, order_total NUMERIC(10,2), created_at TIMESTAMPTZ DEFAULT NOW()); -- Step 2: Enable RLS on the tableALTER TABLE orders ENABLE ROW LEVEL SECURITY; -- Step 3: Create security policy-- current_setting() retrieves session variable set by application CREATE POLICY tenant_isolation ON orders USING (tenant_id = current_setting('app.current_tenant')::INTEGER); -- Alternatively, for role-based multi-tenancy:CREATE POLICY tenant_isolation_v2 ON orders USING (tenant_id = ( SELECT tenant_id FROM user_tenants WHERE user_name = current_user )); -- Step 4: Force RLS for table owner too (important!)ALTER TABLE orders FORCE ROW LEVEL SECURITY; -- Step 5: Create separate policies for different operations -- SELECT: Users see only their tenant's ordersCREATE POLICY orders_select ON orders FOR SELECT USING (tenant_id = current_setting('app.current_tenant')::INTEGER); -- INSERT: Users can only create orders for their tenantCREATE POLICY orders_insert ON orders FOR INSERT WITH CHECK (tenant_id = current_setting('app.current_tenant')::INTEGER); -- UPDATE: Users can only update their tenant's ordersCREATE POLICY orders_update ON orders FOR UPDATE USING (tenant_id = current_setting('app.current_tenant')::INTEGER) WITH CHECK (tenant_id = current_setting('app.current_tenant')::INTEGER); -- DELETE: Users can only delete their tenant's ordersCREATE POLICY orders_delete ON orders FOR DELETE USING (tenant_id = current_setting('app.current_tenant')::INTEGER); -- Step 6: Application sets tenant context-- (Done at connection establishment or transaction start)SET app.current_tenant = '42'; -- Now all queries automatically filter to tenant 42SELECT * FROM orders; -- Only sees tenant 42's ordersINSERT INTO orders (tenant_id, customer_name, order_total) VALUES (99, 'Test', 100.00); -- FAILS: violates RLS policy -- Step 7: View RLS policiesSELECT schemaname, tablename, policyname, permissive, roles, cmd, qual, -- USING clause with_check -- WITH CHECK clauseFROM pg_policiesWHERE tablename = 'orders';RLS predicates are evaluated for every row in every query. Complex predicates involving subqueries or joins can severely impact performance. Always ensure predicate columns are indexed, use SCHEMABINDING (SQL Server) for optimizer benefits, and test with production-scale data. Consider materializing frequently-accessed predicate results.
The Principle of Least Privilege (PoLP) is a foundational security concept: every user, application, and process should have only the minimum privileges necessary to perform its intended function—nothing more.
In database contexts, this means:
Why Least Privilege Matters:
Implementing Least Privilege:
1234567891011121314151617181920212223242526272829303132333435363738394041424344454647484950515253545556575859606162
-- ================================================-- Least Privilege Implementation Strategy-- ================================================ -- ANTI-PATTERN: Overly permissive service account-- DON'T DO THIS:CREATE USER webapp WITH PASSWORD 'secret';GRANT ALL PRIVILEGES ON DATABASE production TO webapp; -- TERRIBLE!GRANT ALL PRIVILEGES ON ALL TABLES IN SCHEMA public TO webapp; -- WORSE! -- ================================================-- CORRECT: Fine-grained privilege assignment-- ================================================ -- Step 1: Start with NO privilegesCREATE USER webapp WITH PASSWORD 'secure_random_password';-- User has no access to anything -- Step 2: Grant only CONNECT (can't even connect without this)GRANT CONNECT ON DATABASE app_db TO webapp; -- Step 3: Grant USAGE on specific schemas (can't see schemas otherwise)GRANT USAGE ON SCHEMA app TO webapp;-- webapp can now see objects in 'app' schema, but can't access them -- Step 4: Grant SELECT on tables needed for read operationsGRANT SELECT ON app.products TO webapp;GRANT SELECT ON app.categories TO webapp;GRANT SELECT ON app.inventory TO webapp; -- Step 5: Grant INSERT/UPDATE only where neededGRANT INSERT ON app.orders TO webapp;GRANT INSERT ON app.order_items TO webapp;GRANT UPDATE (status, shipped_date) ON app.orders TO webapp;-- Note: UPDATE limited to specific columns! -- Step 6: Grant sequence USAGE for inserts with auto-incrementGRANT USAGE ON SEQUENCE app.orders_id_seq TO webapp;GRANT USAGE ON SEQUENCE app.order_items_id_seq TO webapp; -- Step 7: Grant EXECUTE on specific functionsGRANT EXECUTE ON FUNCTION app.calculate_order_total(INTEGER) TO webapp; -- What webapp CANNOT do:-- ❌ Access other schemas-- ❌ Create tables or modify schema-- ❌ DELETE any rows-- ❌ UPDATE columns like price, customer_id-- ❌ Access audit tables-- ❌ Access user credentials -- ================================================-- Review: What privileges does webapp actually have?-- ================================================ SELECT table_schema, table_name, privilege_typeFROM information_schema.table_privilegesWHERE grantee = 'webapp'ORDER BY table_schema, table_name;Privileges accumulate over time as new features are added but rarely removed. Implement quarterly privilege reviews: export current grants, compare against documented requirements, revoke unnecessary privileges. Automate with scripts that flag unusual privilege patterns (users with DBA access, service accounts with DELETE privileges, etc.).
Implementing robust database authorization requires discipline, documentation, and ongoing vigilance. These best practices synthesize decades of enterprise security experience:
| Mistake | Risk | Correction |
|---|---|---|
| GRANT ALL PRIVILEGES | Excessive access, no accountability | Grant only specific required privileges |
| WITH GRANT OPTION | Uncontrolled privilege delegation | Restrict grant option to DBAs only |
| GRANT TO PUBLIC | Every user gets access, including future users | Grant to specific roles only |
| Schema owner = application | Application can modify schema, drop tables | Separate schema owner from runtime account |
| Shared service accounts | No individual accountability | One account per application instance |
| No privilege expiration | Access persists after need ends | Implement access reviews and automatic expiration |
When facing access issues, the temptation to 'just grant more privileges until it works' is strong. This creates cumulative security debt. Instead: diagnose the specific missing privilege, document why it's needed, and grant only that privilege. Short-term convenience creates long-term vulnerability.
Effective authorization isn't just about setting up privileges—it's about continuously verifying that privileges remain appropriate and are being used as expected. Authorization auditing answers critical questions:
123456789101112131415161718192021222324252627282930313233343536373839404142434445464748495051525354555657585960616263646566676869707172737475767778
-- ================================================-- PostgreSQL Authorization Audit Queries-- ================================================ -- 1. All privileges granted on all tablesSELECT grantee, table_schema, table_name, privilege_type, is_grantableFROM information_schema.table_privilegesWHERE table_schema NOT IN ('pg_catalog', 'information_schema')ORDER BY grantee, table_schema, table_name; -- 2. Role memberships (who belongs to which roles)WITH RECURSIVE role_hierarchy AS ( -- Direct memberships SELECT r.rolname AS role_name, m.rolname AS member_name, 1 AS level, ARRAY[r.rolname] AS path FROM pg_roles r JOIN pg_auth_members am ON r.oid = am.roleid JOIN pg_roles m ON m.oid = am.member WHERE r.rolcanlogin = false -- Only group roles UNION ALL -- Inherited memberships SELECT rh.role_name, m.rolname, rh.level + 1, rh.path || m.rolname FROM role_hierarchy rh JOIN pg_auth_members am ON am.roleid = ( SELECT oid FROM pg_roles WHERE rolname = rh.member_name ) JOIN pg_roles m ON m.oid = am.member WHERE NOT m.rolname = ANY(rh.path) -- Prevent cycles)SELECT * FROM role_hierarchy ORDER BY role_name, level; -- 3. Users with superuser privileges (high-risk)SELECT rolname, rolsuper, rolcreaterole, rolcreatedb, rolbypassrlsFROM pg_rolesWHERE rolsuper OR rolcreaterole OR rolcreatedb OR rolbypassrls; -- 4. Tables accessible via PUBLIC roleSELECT table_schema, table_name, privilege_typeFROM information_schema.table_privilegesWHERE grantee = 'PUBLIC' AND table_schema NOT IN ('pg_catalog', 'information_schema'); -- 5. Grant chains (who granted what to whom)SELECT grantor, grantee, table_schema || '.' || table_name AS object, privilege_type, is_grantableFROM information_schema.table_privilegesWHERE table_schema NOT IN ('pg_catalog', 'information_schema')ORDER BY grantor, grantee; -- 6. Unused roles (no members, no privileges)SELECT r.rolnameFROM pg_roles rWHERE NOT r.rolsuper AND NOT r.rolcanlogin AND NOT EXISTS ( SELECT 1 FROM pg_auth_members am WHERE am.roleid = r.oid );Schedule daily exports of privilege configurations and compare against baselines. Flag any new grants, role membership changes, or privilege escalations. Integrate with SIEM systems for real-time alerting on suspicious authorization changes.
Database authorization transforms authenticated identities into controlled access. Let's consolidate the essential knowledge:
What's Next:
Authentication and authorization control who can access data and what they can do. But data at rest and in transit still needs protection. The next page covers Encryption—the cryptographic mechanisms that render data unreadable to anyone without the proper keys, protecting against physical theft, network interception, and insider threats.
You now understand database authorization from discretionary access control through row-level security. You can design RBAC hierarchies, implement fine-grained access policies, apply least privilege principles, and audit authorization configurations. Next, we'll explore encryption as the third pillar of database security.