Monday, October 02, 2023

Row Level Security (RLS) Data Access in Azure SQL Database

We have always seen database level access to the end user but this following walk through will help you to understand How to setup Row Level Security(RLS) access for Azure Active Directory Group (AAD Group) for Table in Azure Database.

This entire SQL scripts developed and tested by myself with AAD Group. There are fours section and follow the each step to achieve your goal.

--********************************************************** 

  --PART 1 Database level User Access RLS AAD

  -- End User Added on below 3 AAD Groups  

--**********************************************************

--Group Name: AZ-AS-GRP1 

--Group Name: AZ-AS-GRP2

--Group Name: AZ-AS-GRP3


  -- STEP 1 Create User

CREATE USER [AZ-AS-GRP1] FROM  EXTERNAL PROVIDER  WITH DEFAULT_SCHEMA=[dbo]

GO

CREATE USER [AZ-AS-GRP2] FROM  EXTERNAL PROVIDER  WITH DEFAULT_SCHEMA=[dbo]

GO

CREATE USER [AZ-AS-GRP3] FROM  EXTERNAL PROVIDER  WITH DEFAULT_SCHEMA=[dbo]

GO

-- STEP 2 Database Role

CREATE ROLE db_RLS_DataReader   AUTHORIZATION [dbo]

GO

--STEP 3 Grant select permission to Database Role

 GRANT SELECT ON OBJECT::RPT.DIM_PRODUCT_SALES TO [db_RLS_DataReader] 


  -- STEP 4 Add an existing user to the role

ALTER ROLE [db_RLS_DataReader] add member  [AZ-AS-GRP1] 

ALTER ROLE [db_RLS_DataReader] add member  [AZ-AS-GRP2]

ALTER ROLE [db_RLS_DataReader] add member  [AZ-AS-GRP3] 

--================================================

 -- Validate the Role

SELECT  

    members.name as 'members_name', 

    roles.name as 'roles_name',

    roles.type_desc as 'roles_desc' ,

    members.type_desc as 'members_desc'

FROM sys.database_role_members rolemem INNER JOIN sys.database_principals roles

ON rolemem.role_principal_id = roles.principal_id

INNER JOIN sys.database_principals members ON rolemem.member_principal_id = members.principal_id

WHERE roles.name ='db_RLS_DataReader'


 --********************************************************** 

 --PART 2 Row Level User Access Table

 --********************************************************** 

 --  STEP 5   RLS User Access Table

CREATE TABLE [RPT].[DIM_DATA_USER_ACCESS](

[ID]  [int]  IDENTITY(1,1) NOT NULL ,

[Assign_Nm]  [varchar](20) NULL,

[AAD_Group_Name]     [nvarchar] (120) NULL,

[User_Email_Id]  [varchar] (60) NULL,

[Is_Active] [bit]  default(1) NULL,

[Deletion_DT] [datetime] NULL, -- 1 Active , 0 InActive

[Created_By]    [varchar](50)  DEFAULT  suser_sname() NULL,

[Created_Date]  [datetime] DEFAULT  getdate()  NULL,

[Modified_By]   [varchar](50)  DEFAULT  suser_sname() NULL,

[Modified_Date] [datetime] DEFAULT  getdate()  NULL,

 CONSTRAINT [PK_ID2] PRIMARY KEY CLUSTERED 

 (

 [ID] ASC

)WITH (STATISTICS_NORECOMPUTE = OFF, IGNORE_DUP_KEY = OFF, OPTIMIZE_FOR_SEQUENTIAL_KEY = OFF) ON [PRIMARY]

) ON [PRIMARY]

GO 

 -- STEP 6: Create the specified users

CREATE USER FULL_DATA WITHOUT LOGIN;

GO

CREATE USER SALES_DATA1 WITHOUT LOGIN;

GO

CREATE USER IT_DATA2 WITHOUT LOGIN;

GO

CREATE USER PRO_DATA3 WITHOUT LOGIN;

GO


 -- INSERT  DATA

SELECT * FROM [RPT].[DIM_DATA_USER_ACCESS]  where User_Email_Id =user_name()

 INSERT INTO [RPT].[DIM_DATA_USER_ACCESS]  (  [ID], [Assign_Nm], [AAD_Group_Name]  , [User_Email_Id])

 VALUES (1, 'SALES_DATA1' , 'AAD1',  'MyUser1@abc.com'  )

 INSERT INTO [RPT].[DIM_DATA_USER_ACCESS]  (  [ID], [Assign_Nm], [AAD_Group_Name]  , [User_Email_Id])

 VALUES (2, 'IT_DATA2',  'AAD2',  'MyUser2@abc.com'     )

 INSERT INTO [RPT].[DIM_DATA_USER_ACCESS]  (  [ID], [Assign_Nm], [AAD_Group_Name]  , [User_Email_Id])

 VALUES (3, 'PRO_DATA3', 'AAD3',  'MyUser3@abc.com' ) 


-- STEP 7 Grant Access to Specified User

GRANT SELECT ON [RPT].[DIM_DATA_USER_ACCESS]  TO FULL_DATA;

GRANT UPDATE ON [RPT].[DIM_DATA_USER_ACCESS]  TO FULL_DATA;

GRANT DELETE ON [RPT].[DIM_DATA_USER_ACCESS]  TO FULL_DATA;

GRANT INSERT ON [RPT].[DIM_DATA_USER_ACCESS]  TO FULL_DATA;


GRANT SELECT ON [RPT].[DIM_DATA_USER_ACCESS]  TO [AZ-AS-GRP1]

GRANT SELECT ON [RPT].[DIM_DATA_USER_ACCESS]  TO [AZ-AS-GRP2]

GRANT SELECT ON [RPT].[DIM_DATA_USER_ACCESS]  TO [AZ-AS-GRP3]


 --********************************************************** 

 --PART 3 Security and Functions

 --********************************************************** 

 -- STEP 8: Create the inline table-valued function

 -- DROP FUNCTION [dbo].[fn_MY_Security]

 --GO 


CREATE FUNCTION  dbo.fn_MY_Security

(@MAPPING_NAME NVARCHAR (255) ) --, @USER_NAME NVARCHAR (255)

RETURNS TABLE

WITH SCHEMABINDING

AS

RETURN 

SELECT 1 AS fn_MY_Security_Result

WHERE @MAPPING_NAME IN 

( SELECT DISTINCT DH.[Assign_Nm]

   FROM [RPT].[DIM_MY_DEPT] AS DH

   INNER JOIN [RPT].[DIM_DATA_USER_ACCESS] AS UA

   ON DH.[Assign_Nm] = UA.[Assign_Nm] 

    WHERE (LOWER( [User_Email_Id])  = LOWER( USER_NAME() ) -- Specific User

AND [Is_Active]=1) OR LOWER( USER_NAME() ) = 'FULL_DATA' -- Admin User

)            

GO


 -- STEP 9: Apply the Security Policy

 -- DROP SECURITY POLICY [dbo].[MY_UserFilter]

 -- GO

CREATE SECURITY POLICY [dbo].[MY_UserFilter]

ADD FILTER PREDICATE   [dbo].fn_MY_Security([Assign_Nm])   

ON [RPT].[DIM_DATA_USER_ACCESS]  

WITH (STATE = ON);

GO

  --********************************************************** 

 --PART 4   Data Validation

  --********************************************************** 

  -- -- STEP 10 Data Validation

-- All data for Admin RLS


EXECUTE AS USER = 'FULL_DATA';

SELECT * FROM  [RPT].[DIM_DATA_USER_ACCESS]

  WHERE AAD_Group_Name LIKE 'AZ%'    

REVERT;

GO


EXECUTE AS USER = 'FULL_DATA';

SELECT * FROM  [RPT].[DIM_DATA_USER_ACCESS]

  WHERE AAD_Group_Name LIKE 'AZ%'     

  ORDER BY 2 

REVERT;

GO


--Specific users

EXECUTE AS USER = 'SALES_DATA1';

SELECT * FROM  [RPT].[DIM_DATA_USER_ACCESS]

REVERT;

GO


EXECUTE AS USER = 'IT_DATA2';

SELECT * FROM  [RPT].[DIM_DATA_USER_ACCESS]

REVERT;

GO


EXECUTE AS USER = 'PRO_DATA3';

SELECT * FROM  [RPT].[DIM_DATA_USER_ACCESS]

REVERT;

GO


 --This catalog view returns all the Security Policies in the database

 --Execute the following statement to get all the security policies in the database with important security policy attributes/columns


SELECT Name, object_id, type, type_desc,is_ms_shipped,is_enabled,is_schema_bound

FROM sys.security_policies

 

--This catalog view returns all the Security Predicates in the database

SELECT * 

FROM sys.security_predicates

Thursday, September 14, 2023

Automatic index management in Azure SQL Database

SELECT  name, desired_state_desc, actual_state_desc, reason_desc

FROM sys.database_automatic_tuning_options

When you enabled automatic index tuning for the Performance Recommendations page will identify indexes that can be created or dropped depending on query performance. Remember this feature isn't available for on-premises databases and It is only available for Azure SQL Database.

Creating new indexes can consume resources, and the timing of the index creations is critical to ensure no negative effect is felt on your workloads.

Azure SQL Database will monitor the resources required to implement new indexes to avoid causing performance degradation. The tuning action is postponed until the available resources are available, for example if resources are required for existing workloads and not available for creating an index.

Monitoring ensures any action taken won't harm performance. If an index is dropped and query performance noticeably degrades, the recently dropped index will be automatically recreated

Thursday, September 07, 2023

Monitor open transactions awaiting commit or rollback run Query

 SELECT tst.session_id, [database_name] = db_name(s.database_id)

    , tat.transaction_begin_time

    , transaction_duration_s = datediff(s, tat.transaction_begin_time, sysdatetime()) 

    , transaction_type = CASE tat.transaction_type  WHEN 1 THEN 'Read/write transaction'

        WHEN 2 THEN 'Read-only transaction'

        WHEN 3 THEN 'System transaction'

        WHEN 4 THEN 'Distributed transaction' END

    , input_buffer = ib.event_info, tat.transaction_uow     

    , transaction_state  = CASE tat.transaction_state    

        WHEN 0 THEN 'The transaction has not been completely initialized yet.'

        WHEN 1 THEN 'The transaction has been initialized but has not started.'

        WHEN 2 THEN 'The transaction is active - has not been committed or rolled back.'

        WHEN 3 THEN 'The transaction has ended. This is used for read-only transactions.'

        WHEN 4 THEN 'The commit process has been initiated on the distributed transaction.'

        WHEN 5 THEN 'The transaction is in a prepared state and waiting resolution.'

        WHEN 6 THEN 'The transaction has been committed.'

        WHEN 7 THEN 'The transaction is being rolled back.'

        WHEN 8 THEN 'The transaction has been rolled back.' END 

    , transaction_name = tat.name, request_status = r.status

    , tst.is_user_transaction, tst.is_local

    , session_open_transaction_count = tst.open_transaction_count  

    , s.host_name, s.program_name, s.client_interface_name, s.login_name, s.is_user_process

FROM sys.dm_tran_active_transactions tat 

INNER JOIN sys.dm_tran_session_transactions tst  on tat.transaction_id = tst.transaction_id

INNER JOIN Sys.dm_exec_sessions s on s.session_id = tst.session_id 

LEFT OUTER JOIN sys.dm_exec_requests r on r.session_id = s.session_id

CROSS APPLY sys.dm_exec_input_buffer(s.session_id, null) AS ib

ORDER BY tat.transaction_begin_time DESC;

Wednesday, May 10, 2023

Update Stats for Table

 SET NOCOUNT  ON 


 DECLARE  @SQLcommand NVARCHAR(512), 

          @Table      SYSNAME 

 DECLARE CurAllTables CURSOR  FOR 

  SELECT table_schema + '.' + table_name 

FROM information_schema.tables T 

       INNER JOIN sys.sysindexes SSI 

ON t.TABLE_NAME = object_name(ssi.id) 

WHERE SSI.rowcnt > 500

    AND SSI.NAME LIKE '%_EN'

 OPEN CurAllTables 

FETCH NEXT FROM CurAllTables 

INTO @Table 

WHILE (@@FETCH_STATUS = 0) 

  BEGIN 

    PRINT N'UPDATING STATISTICS FOR TABLE: ' + @Table 

    SET @SQLcommand = 'UPDATE STATISTICS ' + @Table + ' WITH FULLSCAN' 

    EXEC sp_executesql @SQLcommand 

    FETCH NEXT FROM CurAllTables 

    INTO @Table 

  END 

CLOSE CurAllTables 

DEALLOCATE CurAllTables 


SET NOCOUNT  OFF 

GO

Tuesday, May 09, 2023

Find Index Fragmentation in Table

 SELECT 

S.name as 'Schema_Name',

T.name as 'Table_Name',

I.name as 'Index_Name',

F.Avg_Fragmentation_in_Percent,

F.Page_Count

FROM sys.dm_db_index_physical_stats (DB_ID(), NULL, NULL, NULL, NULL) as F

INNER JOIN sys.tables  as T    ON T.object_id = F.object_id

INNER JOIN sys.schemas as S ON T.schema_id = S.schema_id

INNER JOIN sys.indexes as I   ON I.object_id = F.object_id

AND F.index_id = I.index_id

WHERE F.database_id = DB_ID()

AND I.name IS NOT NULL

AND F.avg_fragmentation_in_percent > 0

ORDER BY F.avg_fragmentation_in_percent DESC

Friday, January 13, 2023

Azure SQL Indexes and Statistics

Maintaining index with low fragmentation is significant performance improvement in any SQL databases.

You can check and download scripts from Azure Database Blog from author  Yochanan Rachamim.

How to maintain Azure SQL Indexes and Statistics - Microsoft Community Hub