|
| 1 | +-- ============================================================================= |
| 2 | +-- CREATE VIEW v_oidc_users (MS SQL Server Version) |
| 3 | +-- ============================================================================= |
| 4 | +-- This script creates a read-only view exposing only necessary authuser fields for OIDC |
| 5 | +-- |
| 6 | +-- PREREQUISITES: |
| 7 | +-- - Database must exist and you must be connected to it |
| 8 | +-- - Tables 'authuser' and 'resourceuser' must exist |
| 9 | +-- - User/Login for OIDC service must be created beforehand |
| 10 | +-- |
| 11 | +-- TODO: Consider excluding locked users by joining with mappedbadloginattempt table |
| 12 | +-- and checking mbadattemptssinceresetorsuccess against max.bad.login.attempts prop |
| 13 | +-- |
| 14 | +-- USAGE: |
| 15 | +-- 1. Connect to your target database |
| 16 | +-- 2. Run this script to create the view |
| 17 | +-- 3. Manually grant permissions: GRANT SELECT ON v_oidc_users TO [your_oidc_user]; |
| 18 | + |
| 19 | +-- Drop the view if it already exists |
| 20 | +IF OBJECT_ID('dbo.v_oidc_users', 'V') IS NOT NULL |
| 21 | + DROP VIEW dbo.v_oidc_users; |
| 22 | +GO |
| 23 | + |
| 24 | +-- Create a read-only view exposing only necessary authuser fields for OIDC |
| 25 | +CREATE VIEW dbo.v_oidc_users AS |
| 26 | +SELECT |
| 27 | + ru.userid_ AS user_id, |
| 28 | + au.username, |
| 29 | + au.firstname, |
| 30 | + au.lastname, |
| 31 | + au.email, |
| 32 | + au.validated, |
| 33 | + au.provider, |
| 34 | + au.password_pw, |
| 35 | + au.password_slt, |
| 36 | + au.createdat, |
| 37 | + au.updatedat |
| 38 | +FROM dbo.authuser au |
| 39 | +INNER JOIN dbo.resourceuser ru ON au.user_c = ru.id |
| 40 | +WHERE au.validated = 1; -- Only expose validated users to OIDC service (1 = true in MS SQL Server) |
| 41 | +GO |
| 42 | + |
| 43 | +-- Add extended property to the view for documentation |
| 44 | +EXEC sp_addextendedproperty |
| 45 | + @name = N'MS_Description', |
| 46 | + @value = N'Read-only view of authuser and resourceuser tables for OIDC service access. Only includes validated users and returns user_id from resourceuser.userid_. WARNING: Includes password hash and salt for OIDC credential verification - ensure secure access.', |
| 47 | + @level0type = N'SCHEMA', @level0name = 'dbo', |
| 48 | + @level1type = N'VIEW', @level1name = 'v_oidc_users'; |
| 49 | +GO |
| 50 | + |
| 51 | +-- Grant SELECT permission on the OIDC view |
| 52 | +-- IMPORTANT: Replace 'oidc_user' with your actual OIDC database user/login name |
| 53 | +-- Uncomment and modify the following line: |
| 54 | +-- GRANT SELECT ON dbo.v_oidc_users TO [oidc_user]; |
| 55 | +-- GO |
| 56 | + |
| 57 | +PRINT 'OIDC users view created successfully.'; |
| 58 | +GO |
0 commit comments