├── Dynamic_Query ├── 1.Create_Dynamic_Table.sql ├── 2.Drop_Recreate_Foreign_Keys.sql └── 3.Dynamic_Pivot.sql ├── LICENSE ├── Purging └── 1.Purge_All_Tables_With_FK.sql ├── README.md ├── T-SQL_Enhancements_2022 ├── 1.IS DISTINCT FROM.sql ├── 2.DATE BUCKET Function.sql ├── 3.DATETRUNC.sql ├── 4.LEAST and GREATEST.sql ├── 5.STRING_SPLIT.sql ├── 6.TRIM.sql ├── 7.GENERATE_SERIES.sql ├── 8.WINDOWS Function.sql └── 9.BIT Function.sql └── TEMPDB_Query ├── 1.TEMPDB_Query_Exec_Plan.sql ├── 2.TEMPDB_Cleanup.sql └── 3.TEMPDB_Usage.sql /Dynamic_Query/1.Create_Dynamic_Table.sql: -------------------------------------------------------------------------------- 1 | DECLARE @SqlStart NVARCHAR(max) = '' 2 | DECLARE @sql NVARCHAR(max) = '' 3 | DECLARE @sqlEnd NVARCHAR(max) = '' 4 | DECLARE @table VARCHAR(max) = 'DatabaseLog' 5 | 6 | 7 | SET @SqlStart = 'CREATE TABLE [' + @table + '] (' + CHAR(13) 8 | 9 | SELECT @sql = @sql + a.Column_Name + ' ' 10 | + Data_Type 11 | + CASE WHEN CHARACTER_MAXIMUM_LENGTH IS NULL or DATA_TYPE = 'xml' THEN '' ELSE '(' + CASE WHEN CHARACTER_MAXIMUM_LENGTH>0 THEN CAST(CHARACTER_MAXIMUM_LENGTH AS VARCHAR(10)) ELSE 'max' END +')' END 12 | + CASE WHEN NUMERIC_PRECISION IS NULL OR DATA_TYPE in ('Int', 'tinyint', 'bigint', 'smallint') THEN '' ELSE '(' + CAST(NUMERIC_PRECISION AS VARCHAR(10)) +','+CAST(NUMERIC_SCALE AS VARCHAR(10)) +')' END 13 | + CASE WHEN EXISTS ( SELECT id from sys.syscolumns WHERE OBJECT_NAME(id)=@table AND name=a.column_name AND COLUMNPROPERTY(id,name,'IsIdentity') = 1 ) THEN ' IDENTITY(' + CAST(IDENT_SEED(@table) AS VARCHAR) + ',' + CAST(IDENT_INCR(@table) AS VARCHAR) + ')' ELSE '' END 14 | + CASE WHEN b.default_value is not null THEN ' DEFAULT ' + SUBSTRING(b.default_value, 2, LEN(b.default_value)-2) + ' ' ELSE '' END 15 | + CASE WHEN IS_NULLABLE = 'NO' THEN ' NOT NULL' ELSE ' NULL ' END + CHAR(13) + ',' 16 | FROM INFORMATION_SCHEMA.COLUMNS a 17 | JOIN ( 18 | SELECT so.name AS table_name, 19 | sc.name AS column_name, 20 | sm.text AS default_value 21 | FROM sys.sysobjects so 22 | JOIN sys.syscolumns sc ON sc.id = so.id 23 | LEFT JOIN sys.syscomments SM ON sm.id = sc.cdefault 24 | WHERE so.xtype = 'U' 25 | AND SO.name = @table) b 26 | ON b.column_name = a.COLUMN_NAME 27 | AND b.table_name = a.TABLE_NAME 28 | WHERE a.Table_Name = @table 29 | 30 | IF((SELECT COUNT(1) FROM INFORMATION_SCHEMA.TABLE_CONSTRAINTS WHERE TABLE_NAME = @table) >0) 31 | BEGIN 32 | SELECT @sqlEnd = CHAR(13) + 'CONSTRAINT [PK_' + @table + '_1] PRIMARY KEY NONCLUSTERED' + 33 | CHAR(13) +'(' + CHAR(13) + Column_Name + ' ASC ' + CHAR(13) + ') WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, IGNORE_DUP_KEY = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON) ON [PRIMARY]) ON [PRIMARY]' 34 | FROM INFORMATION_SCHEMA.KEY_COLUMN_USAGE WHERE TABLE_NAME = @table 35 | 36 | SET @Sql = @SqlStart + SUBSTRING(@sql, 0, LEN(@sql)-1) + @sqlEnd 37 | END 38 | ELSE 39 | BEGIN 40 | SET @Sql = @SqlStart + SUBSTRING(@sql, 0, LEN(@sql)-1) + ')' 41 | END 42 | 43 | PRINT @sql -------------------------------------------------------------------------------- /Dynamic_Query/2.Drop_Recreate_Foreign_Keys.sql: -------------------------------------------------------------------------------- 1 | USE [Databasename] 2 | GO 3 | 4 | DECLARE @tablename AS NVARCHAR(255) = 'tablename' 5 | DECLARE @keyColumnname AS NVARCHAR(255) = 'Keycolumnname' 6 | 7 | SELECT 8 | 'ALTER TABLE [dbo].[' + OBJECT_NAME(f.parent_object_id) + '] Drop Constraint [' + F.Name + ']' 9 | -- ,* 10 | -- ,OBJECT_NAME(f.parent_object_id) TableName, 11 | -- COL_NAME(fc.parent_object_id,fc.parent_column_id) ColName 12 | FROM sys.foreign_keys AS f 13 | INNER JOIN sys.foreign_key_columns AS fc 14 | ON f.OBJECT_ID = fc.constraint_object_id 15 | INNER JOIN sys.tables t 16 | ON t.OBJECT_ID = fc.referenced_object_id 17 | INNER JOIN sys.columns S 18 | ON S.Column_ID = fc.Parent_column_ID 19 | AND S.object_ID = f.parent_object_id 20 | WHERE OBJECT_NAME (f.referenced_object_id) = @tablename 21 | 22 | SELECT 23 | 'ALTER TABLE [dbo].[' + OBJECT_NAME(f.parent_object_id) + '] WITH NOCHECK ADD CONSTRAINT [' + F.Name + '] FOREIGN KEY (' + S.Name + ') REFERENCES '+ @tablename +'('+@keyColumnname+')' 24 | -- ,* 25 | -- ,OBJECT_NAME(f.parent_object_id) TableName, 26 | -- COL_NAME(fc.parent_object_id,fc.parent_column_id) ColName 27 | FROM sys.foreign_keys AS f 28 | INNER JOIN sys.foreign_key_columns AS fc 29 | ON f.OBJECT_ID = fc.constraint_object_id 30 | INNER JOIN sys.tables t 31 | ON t.OBJECT_ID = fc.referenced_object_id 32 | INNER JOIN sys.columns S 33 | ON S.Column_ID = fc.Parent_column_ID 34 | AND S.object_ID =f.parent_object_id 35 | WHERE OBJECT_NAME (f.referenced_object_id) = @tablename 36 | 37 | SELECT 38 | 'ALTER TABLE [dbo].[' + OBJECT_NAME(f.parent_object_id) + '] CHECK Constraint [' + F.Name + ']' 39 | -- ,* 40 | -- , OBJECT_NAME(f.parent_object_id) TableName, 41 | -- COL_NAME(fc.parent_object_id,fc.parent_column_id) ColName 42 | FROM sys.foreign_keys AS f 43 | INNER JOIN sys.foreign_key_columns AS fc 44 | ON f.OBJECT_ID = fc.constraint_object_id 45 | INNER JOIN sys.tables t 46 | ON t.OBJECT_ID = fc.referenced_object_id 47 | INNER JOIN sys.columns S 48 | ON S.Column_ID = fc.Parent_column_ID 49 | AND S.object_ID =f.parent_object_id 50 | WHERE OBJECT_NAME (f.referenced_object_id) = @tablename -------------------------------------------------------------------------------- /Dynamic_Query/3.Dynamic_Pivot.sql: -------------------------------------------------------------------------------- 1 | DROP TABLE IF EXISTS #Tmp_Dynamci_Pivot 2 | CREATE TABLE #Tmp_Dynamci_Pivot ([Id] int, [ColumnName] NVARCHAR(20), [Value] NVARCHAR(20)) 3 | 4 | INSERT INTO #Tmp_Dynamci_Pivot ([Id], [ColumnName], [Value]) 5 | SELECT 1,'Id','1001' 6 | UNION 7 | SELECT 2,'Name','Dynamic Pivot' 8 | UNION 9 | SELECT 3,'Type','Blog' 10 | UNION 11 | SELECT 4,'Status','Active' 12 | UNION 13 | SELECT 5,'CreatedMonth','July' 14 | 15 | DECLARE @PivotColumns NVARCHAR(100) 16 | DECLARE @PivotQuery NVARCHAR(500) 17 | 18 | SELECT @PivotColumns = STRING_AGG(QUOTENAME([ColumnName]),', ') 19 | FROM( SELECT 1 AS Id, [ColumnName] FROM #Tmp_Dynamci_Pivot ) P 20 | GROUP BY ID 21 | 22 | SET @PivotQuery = N'SELECT ' + @PivotColumns + 23 | N' from ( SELECT [ColumnName],[Value] FROM #Tmp_Dynamci_Pivot ) A 24 | PIVOT 25 | ( 26 | MAX([value]) 27 | FOR [ColumnName] IN (' + @PivotColumns + N') 28 | ) AA ' 29 | 30 | EXEC sp_executesql @PivotQuery 31 | 32 | -------------------------------------------------------------------------------- /LICENSE: -------------------------------------------------------------------------------- 1 | MIT License 2 | 3 | Copyright (c) 2024 Naveen Kumar M 4 | 5 | Permission is hereby granted, free of charge, to any person obtaining a copy 6 | of this software and associated documentation files (the "Software"), to deal 7 | in the Software without restriction, including without limitation the rights 8 | to use, copy, modify, merge, publish, distribute, sublicense, and/or sell 9 | copies of the Software, and to permit persons to whom the Software is 10 | furnished to do so, subject to the following conditions: 11 | 12 | The above copyright notice and this permission notice shall be included in all 13 | copies or substantial portions of the Software. 14 | 15 | THE SOFTWARE IS PROVIDED "AS IS", WITHOUT WARRANTY OF ANY KIND, EXPRESS OR 16 | IMPLIED, INCLUDING BUT NOT LIMITED TO THE WARRANTIES OF MERCHANTABILITY, 17 | FITNESS FOR A PARTICULAR PURPOSE AND NONINFRINGEMENT. IN NO EVENT SHALL THE 18 | AUTHORS OR COPYRIGHT HOLDERS BE LIABLE FOR ANY CLAIM, DAMAGES OR OTHER 19 | LIABILITY, WHETHER IN AN ACTION OF CONTRACT, TORT OR OTHERWISE, ARISING FROM, 20 | OUT OF OR IN CONNECTION WITH THE SOFTWARE OR THE USE OR OTHER DEALINGS IN THE 21 | SOFTWARE. 22 | -------------------------------------------------------------------------------- /Purging/1.Purge_All_Tables_With_FK.sql: -------------------------------------------------------------------------------- 1 | USE AdventureWorks2022 2 | GO 3 | 4 | --Retrieve all tables with foreign keys, excluding those that are self-referencing 5 | ;WITH CTE_Get_Tables_With_FK 6 | AS ( 7 | SELECT 8 | FK.[parent_object_id] AS [parent_object_id] 9 | ,SCM.[name] AS [Parent_SchemaName] 10 | ,TBL.[name] AS [Parent_TableName] 11 | ,FK.[referenced_object_id] AS [Ref_object_id] 12 | ,RSCM.[name] AS [Ref_SchemaName] 13 | ,RTBL.[name] AS [Ref_TableName] 14 | FROM sys.foreign_keys FK 15 | INNER JOIN sys.tables TBL ON TBL.[object_id] = FK.[parent_object_id] 16 | INNER JOIN sys.schemas SCM ON SCM.[schema_id] = TBL.[schema_id] 17 | INNER JOIN sys.tables RTBL ON RTBL.[object_id] = FK.[referenced_object_id] 18 | INNER JOIN sys.schemas RSCM ON RSCM.[schema_id] = RTBL.[schema_id] 19 | WHERE FK.[type] = 'F' 20 | AND FK.[parent_object_id] <> [referenced_object_id] 21 | AND TBL.type = 'U' 22 | AND RTBL.type = 'U' 23 | ) 24 | 25 | /* 26 | Recursive CTE: Identify the sequence of each referenced table. 27 | For example, if Table1 references Table2, and Table2 references Table3, then assign the sequence as follows: Table3 should be assigned a sequence of 1, Table2 a sequence of 2, and Table1 a sequence of 3. 28 | */ 29 | ,CTE_Get_All_Ref_Table_In_Sequence 30 | AS ( 31 | SELECT FK1.[parent_object_id] 32 | ,FK1.[Parent_SchemaName] 33 | ,FK1.[Parent_TableName] 34 | ,FK1.[Ref_object_id] 35 | ,FK1.[Ref_SchemaName] 36 | ,FK1.[Ref_TableName] 37 | ,1 AS [Iteration_Sequence_No] 38 | FROM CTE_Get_Tables_With_FK FK1 39 | LEFT JOIN CTE_Get_Tables_With_FK FK2 ON FK1.[parent_object_id] = FK2.[Ref_object_id] 40 | WHERE FK2.[parent_object_id] IS NULL 41 | 42 | UNION ALL 43 | 44 | SELECT FK.[parent_object_id] 45 | ,FK.[Parent_SchemaName] 46 | , FK.[Parent_TableName] 47 | , FK.[Ref_object_id] 48 | , FK.[Ref_SchemaName] 49 | , FK.[Ref_TableName] 50 | , CTE.[Iteration_Sequence_No] + 1 AS [Iteration_Sequence_No] 51 | FROM CTE_Get_Tables_With_FK FK 52 | INNER JOIN CTE_Get_All_Ref_Table_In_Sequence CTE ON FK.[parent_object_id] = CTE.[Ref_object_id] 53 | WHERE FK.[Ref_object_id] <> CTE.[parent_object_id] 54 | ) 55 | 56 | --Retrieve the distinct parent tables along with their iteration sequence numbers 57 | ,CTE_Get_Unique_Parent_Table_With_Ref 58 | AS ( 59 | SELECT DISTINCT [Parent_SchemaName] 60 | ,[Parent_TableName] 61 | ,[parent_object_id] 62 | ,[Iteration_Sequence_No] 63 | FROM CTE_Get_All_Ref_Table_In_Sequence 64 | ) 65 | 66 | --Combine all tables, including those with foreign keys and those without foreign keys. 67 | , CTE_Get_All_Tables 68 | AS ( 69 | SELECT SCM.[name] AS [SchemaName] 70 | ,TBL.[name] AS [TableName] 71 | ,ISNULL(Prnt_Tbl_Ref.[Iteration_Sequence_No], (ISNULL(MITRN.[Max_Iteration_Sequence_No], 0) + 1)) AS [Iteration_Sequence_No] 72 | ,CASE WHEN EXISTS (SELECT 1 FROM CTE_Get_Tables_With_FK WHERE [Ref_object_id] = TBL.[object_id]) THEN 1 ELSE 0 END AS [Table_Has_Ref] 73 | FROM sys.tables TBL 74 | INNER JOIN sys.schemas SCM ON SCM.[schema_id] = TBL.[schema_id] 75 | LEFT JOIN CTE_Get_Unique_Parent_Table_With_Ref Prnt_Tbl_Ref ON Prnt_Tbl_Ref.[parent_object_id] = TBL.[object_id] 76 | OUTER APPLY ( SELECT MAX([Iteration_Sequence_No]) AS [Max_Iteration_Sequence_No] FROM CTE_Get_Unique_Parent_Table_With_Ref ) MITRN 77 | WHERE TBL.[type] = 'U' 78 | AND TBL.[name] NOT LIKE 'sys%' 79 | ) 80 | /* 81 | Output: SchemaName, TableName, and T-SQL script to purge the table data. TRUNCATE is used where there are no foreign key references, otherwise, DELETE is used. 82 | */ 83 | SELECT TBL_SEQ.[SchemaName] 84 | ,TBL_SEQ.[TableName] 85 | ,TBL_SEQ.[Iteration_Sequence_No] 86 | ,(CASE WHEN ROW_NUMBER() OVER (ORDER BY TBL_SEQ.[Iteration_Sequence_No] ASC) = 1 THEN 'SET NOCOUNT ON;' ELSE '' END) + CHAR(13) + CHAR(10) + 87 | (CASE WHEN TBL_SEQ.[Table_Has_Ref] = 0 THEN 'TRUNCATE TABLE ' + QUOTENAME(TBL_SEQ.[SchemaName]) + '.' + QUOTENAME(TBL_SEQ.[TableName]) + ';' 88 | ELSE 'DELETE FROM ' + QUOTENAME(TBL_SEQ.[SchemaName]) + '.' + QUOTENAME(TBL_SEQ.[TableName]) + ';' + CHAR(13) + CHAR(10) + 'GO' + CHAR(13) + CHAR(10) + 89 | 'DBCC CHECKIDENT (''' + QUOTENAME(TBL_SEQ.[SchemaName]) + '.' + QUOTENAME(TBL_SEQ.[TableName]) + ''', RESEED, 1);' 90 | END + CHAR(13) + CHAR(10) + 'GO') AS [TSQL_Query] 91 | FROM CTE_Get_All_Tables TBL_SEQ 92 | ORDER BY TBL_SEQ.[Iteration_Sequence_No] ASC, TBL_SEQ.[SchemaName] ASC, TBL_SEQ.[TableName] ASC 93 | OPTION (MAXRECURSION 0) -------------------------------------------------------------------------------- /README.md: -------------------------------------------------------------------------------- 1 | # Awesome SQL Master Mind 2 | 3 | Welcome to **Awesome SQL Master Mind**! 🚀 This repository is your go-to hub for powerful SQL queries and scripts, specially curated for developers, data engineers, and DBAs. Whether you're looking to optimize performance, manage tempdb, explore new T-SQL enhancements, or master dynamic queries, you'll find valuable resources here. 4 | 5 | --- 6 | 7 | ## 📂 Repository Structure 8 | 9 | ### Available Folders 10 | - **Dynamic_Query** - Scripts to build dynamic SQL queries on the fly. 11 | - **Purging** - Queries for data purging and cleanup strategies. 12 | - **T-SQL_Enhancements_2022** - Examples and usage of the latest T-SQL enhancements available in SQL Server 2022. 13 | - **TEMPDB_Query** - Insights and queries focused on monitoring and managing tempdb effectively. 14 | 15 | ## 💡 Why Use This Repo? 16 | 17 | SQL mastery requires constant learning and exploration of best practices and new features. **Awesome SQL Master Mind** helps by: 18 | - Providing ready-to-use SQL scripts and examples. 19 | - Offering optimized queries to enhance performance. 20 | - Keeping you updated with the latest T-SQL features. 21 | 22 | ## 🔥 Key Features 23 | 24 | - **Developer-Focused Queries**: Solutions for day-to-day development needs. 25 | - **Data Engineering Tools**: Helpful for ETL, transformations, and data pipeline optimization. 26 | - **Performance Tuning**: Advanced queries to help DBAs keep databases fast and efficient. 27 | - **Latest T-SQL Enhancements**: Stay ahead with cutting-edge SQL Server features. 28 | 29 | ## 🚀 Getting Started 30 | 31 | 1. Clone the repository: 32 | ```bash 33 | git clone https://github.com/navindevan/awesome-sql-master-mind.git 34 | 2. Explore the folders to find queries and scripts tailored to your needs. 35 | 3. Modify and use them in your projects. 36 | 37 | ## 📜 License 38 | 39 | This project is licensed under the MIT License. See the [LICENSE.md](LICENSE) file for details. 40 | 41 | ## 📞 Connect 42 | 43 | For feedback, questions, or more SQL tips, connect with me: 44 | 45 | 🔗 [LinkedIn](https://www.linkedin.com/in/naveenkumarm): Let's connect and discuss database strategies! 46 | 47 | ▶️ [YouTube Channel](https://www.youtube.com/@ttwithnaveen): Subscribe for more database insights and tutorials. 48 | 49 | -------------------------------------------------------------------------------- /T-SQL_Enhancements_2022/1.IS DISTINCT FROM.sql: -------------------------------------------------------------------------------- 1 | USE [AdventureWorks2022] 2 | GO 3 | 4 | CREATE TABLE [dbo].[Employees]( 5 | [EmployeeID] [int] NULL, 6 | [Salary] [decimal](10, 2) NULL, 7 | [Bonus] [decimal](10, 2) NULL 8 | ) ON [PRIMARY] 9 | GO 10 | 11 | INSERT [dbo].[Employees] ([EmployeeID], [Salary], [Bonus]) VALUES (1, CAST(50000.00 AS Decimal(10, 2)), CAST(5000.00 AS Decimal(10, 2))) 12 | INSERT [dbo].[Employees] ([EmployeeID], [Salary], [Bonus]) VALUES (2, CAST(60000.00 AS Decimal(10, 2)), NULL) 13 | INSERT [dbo].[Employees] ([EmployeeID], [Salary], [Bonus]) VALUES (3, NULL, NULL) 14 | INSERT [dbo].[Employees] ([EmployeeID], [Salary], [Bonus]) VALUES (4, CAST(55000.00 AS Decimal(10, 2)), CAST(5500.00 AS Decimal(10, 2))) 15 | INSERT [dbo].[Employees] ([EmployeeID], [Salary], [Bonus]) VALUES (5, NULL, CAST(3000.00 AS Decimal(10, 2))) 16 | GO 17 | 18 | --Syntax: value1 IS DISTINCT FROM value2 19 | --TRUE if the two values are different, including cases where one value is NULL and the other is not. 20 | --FALSE if the two values are the same, including cases where both values are NULL. 21 | 22 | --Syntax: value1 IS NOT DISTINCT FROM value2 23 | --TRUE if the two values are the same, including cases where both values are NULL. 24 | --FALSE if the two values are different, including cases where one value is NULL and the other is not. 25 | 26 | --Traditional Approach 27 | SELECT 28 | EmployeeID, 29 | CASE 30 | WHEN Salary IS NULL AND Bonus IS NULL THEN 'Equal' 31 | WHEN Salary = Bonus THEN 'Equal' 32 | ELSE 'Distinct' 33 | END AS ComparisonResult 34 | FROM dbo.Employees 35 | 36 | --Using IS DISTINCT FROM 37 | SELECT 38 | EmployeeID, 39 | CASE 40 | WHEN Salary IS DISTINCT FROM Bonus THEN 'Distinct' 41 | ELSE 'Equal' 42 | END AS ComparisonResult 43 | FROM dbo.Employees 44 | 45 | --Using IS NOT DISTINCT FROM 46 | --Data Deduplication: For example, to identify duplicate rows in a table with nullable columns. 47 | ;WITH DuplicateRows AS ( 48 | SELECT 49 | EmployeeID, 50 | ROW_NUMBER() OVER (PARTITION BY Salary, Bonus ORDER BY EmployeeID) AS RowNum 51 | FROM dbo.Employees 52 | WHERE Salary IS NOT DISTINCT FROM Bonus 53 | ) 54 | DELETE FROM DuplicateRows WHERE RowNum > 1 55 | 56 | --Conditional Updates and Inserts - For example, to update the Bonus column only if it is distinct from the Salary column. 57 | UPDATE dbo.Employees 58 | SET Bonus = Salary * 0.1 59 | WHERE Salary IS DISTINCT FROM Bonus; 60 | 61 | --Data Comparison and Synchronization 62 | SELECT 63 | a.EmployeeID, 64 | a.Salary AS SalaryInTableA, 65 | b.Salary AS SalaryInTableB 66 | FROM dbo.Employees a 67 | JOIN dbo.Employees1 b 68 | ON a.EmployeeID = b.EmployeeID 69 | WHERE a.Salary IS DISTINCT FROM b.Salary; -------------------------------------------------------------------------------- /T-SQL_Enhancements_2022/2.DATE BUCKET Function.sql: -------------------------------------------------------------------------------- 1 | USE AdventureWorks2022 2 | GO 3 | 4 | --Syntax: DATE_BUCKET (datepart, number, date [, origin ] ) 5 | --datepart: The part of the date you want to group by, such as a day, week, month, etc. This can be 6 | --number: The size of the time bucket, which must be an integer. year, month, week, day, hour, minute, second, millisecond, etc. 7 | --date: The date to be truncated and grouped by the interval and datepart. 8 | 9 | 10 | --Month Interval Example 11 | --This example groups dates into 2-month intervals, starting from January 1, 2024. 12 | DECLARE @DateOrigin date = '2024-01-01' 13 | SELECT 14 | '1/2m' = DATE_BUCKET(MONTH, 2, CONVERT(date, '2024-01-01'), @DateOrigin), 15 | '1/2m' = DATE_BUCKET(MONTH, 2, CONVERT(date, '2024-02-01'), @DateOrigin), 16 | '2/2m' = DATE_BUCKET(MONTH, 2, CONVERT(date, '2024-03-01'), @DateOrigin), 17 | '2/2m' = DATE_BUCKET(MONTH, 2, CONVERT(date, '2024-04-01'), @DateOrigin), 18 | '1/2m' = DATE_BUCKET(MONTH, 2, CONVERT(date, '2024-05-01'), @DateOrigin), 19 | '1/2m' = DATE_BUCKET(MONTH, 2, CONVERT(date, '2024-06-01'), @DateOrigin), 20 | '2/2m' = DATE_BUCKET(MONTH, 2, CONVERT(date, '2024-07-01'), @DateOrigin), 21 | '2/2m' = DATE_BUCKET(MONTH, 2, CONVERT(date, '2024-08-01'), @DateOrigin) 22 | GO 23 | 24 | --Week Interval Example 25 | --This example groups dates into 2-week intervals, starting from January 1, 2024. 26 | DECLARE @DateOrigin date = '2024-01-01' 27 | SELECT 28 | '1/2w' = DATE_BUCKET(WEEK, 2, CONVERT(date, '2024-01-01'), @DateOrigin), 29 | '1/2w' = DATE_BUCKET(WEEK, 2, CONVERT(date, '2024-01-08'), @DateOrigin), 30 | '2/2w' = DATE_BUCKET(WEEK, 2, CONVERT(date, '2024-01-15'), @DateOrigin), 31 | '2/2w' = DATE_BUCKET(WEEK, 2, CONVERT(date, '2024-01-22'), @DateOrigin), 32 | '1/2w' = DATE_BUCKET(WEEK, 2, CONVERT(date, '2024-01-29'), @DateOrigin), 33 | '1/2w' = DATE_BUCKET(WEEK, 2, CONVERT(date, '2024-02-05'), @DateOrigin), 34 | '2/2w' = DATE_BUCKET(WEEK, 2, CONVERT(date, '2024-02-12'), @DateOrigin), 35 | '2/2w' = DATE_BUCKET(WEEK, 2, CONVERT(date, '2024-02-19'), @DateOrigin) 36 | GO 37 | 38 | --Day Interval Example 39 | --This example groups dates into 2-day intervals, starting from January 1, 2022. 40 | DECLARE @DateOrigin date = '2024-01-01' 41 | SELECT 42 | '1/2d' = DATE_BUCKET(DAY, 2, CONVERT(date, '2024-01-01'), @DateOrigin), 43 | '2/2d' = DATE_BUCKET(DAY, 2, CONVERT(date, '2024-01-02'), @DateOrigin), 44 | '1/2d' = DATE_BUCKET(DAY, 2, CONVERT(date, '2024-01-03'), @DateOrigin), 45 | '2/2d' = DATE_BUCKET(DAY, 2, CONVERT(date, '2024-01-04'), @DateOrigin), 46 | '1/2d' = DATE_BUCKET(DAY, 2, CONVERT(date, '2024-01-05'), @DateOrigin), 47 | '2/2d' = DATE_BUCKET(DAY, 2, CONVERT(date, '2024-01-06'), @DateOrigin), 48 | '1/2d' = DATE_BUCKET(DAY, 2, CONVERT(date, '2024-01-07'), @DateOrigin), 49 | '2/2d' = DATE_BUCKET(DAY, 2, CONVERT(date, '2024-01-08'), @DateOrigin) 50 | GO 51 | 52 | --Grouping Sales Data by Weekly Buckets 53 | SELECT 54 | DATE_BUCKET(WEEK, 1, OrderDate) AS OrderWeek, 55 | COUNT(SalesOrderID) AS TotalOrders, 56 | SUM(TotalDue) AS TotalSales 57 | FROM Sales.SalesOrderHeader 58 | GROUP BY DATE_BUCKET(WEEK, 1, OrderDate) 59 | ORDER BY OrderWeek 60 | 61 | --Monthly Sales Data Analysis 62 | SELECT 63 | DATE_BUCKET(MONTH, 1, OrderDate) AS OrderMonth, 64 | COUNT(SalesOrderID) AS TotalOrders, 65 | SUM(TotalDue) AS TotalSales 66 | FROM Sales.SalesOrderHeader 67 | GROUP BY DATE_BUCKET(MONTH, 1, OrderDate) 68 | ORDER BY OrderMonth 69 | 70 | --Grouping Data in Custom Intervals (e.g., 10-Day Buckets) 71 | SELECT 72 | DATE_BUCKET(DAY, 10, OrderDate) AS OrderPeriod, 73 | COUNT(SalesOrderID) AS TotalOrders, 74 | SUM(TotalDue) AS TotalSales 75 | FROM Sales.SalesOrderHeader 76 | GROUP BY DATE_BUCKET(DAY, 10, OrderDate) 77 | ORDER BY OrderPeriod 78 | 79 | --DATEADD and DATEDIFF 80 | SELECT 81 | DATEADD(YEAR, DATEDIFF(YEAR, 0, OrderDate), 0) AS OrderYear, 82 | COUNT(SalesOrderID) AS TotalOrders, 83 | SUM(TotalDue) AS TotalSales 84 | FROM Sales.SalesOrderHeader 85 | GROUP BY DATEADD(YEAR, DATEDIFF(YEAR, 0, OrderDate), 0) 86 | 87 | --FLOOR or CEILING on Date Calculations 88 | SELECT 89 | FLOOR(DATEDIFF(DAY, '1900-01-01', OrderDate) / 7) AS WeekNumber, 90 | COUNT(SalesOrderID) AS TotalOrders 91 | FROM Sales.SalesOrderHeader 92 | GROUP BY FLOOR(DATEDIFF(DAY, '1900-01-01', OrderDate) / 7) -------------------------------------------------------------------------------- /T-SQL_Enhancements_2022/3.DATETRUNC.sql: -------------------------------------------------------------------------------- 1 | USE AdventureWorks2022 2 | GO 3 | 4 | --Syntax: DATETRUNC ( datepart, expression ) 5 | --datepart: The part of the date to truncate. This can be year, quarter, month, day, hour, minute, second, etc. 6 | --expression: The datetime, smalldatetime, date, or datetime2 expression to truncate. 7 | 8 | DECLARE @date datetime2 = '2024-10-08 13:45:30.123' 9 | 10 | -- Truncate to year 11 | SELECT DATETRUNC(year, @date) AS TruncatedToYear 12 | 13 | -- Truncate to month 14 | SELECT DATETRUNC(month, @date) AS TruncatedToMonth 15 | 16 | -- Truncate to day 17 | SELECT DATETRUNC(day, @date) AS TruncatedToDay 18 | 19 | -- Truncate to hour 20 | SELECT DATETRUNC(hour, @date) AS TruncatedToHour 21 | 22 | -- Truncate to minute 23 | SELECT DATETRUNC(minute, @date) AS TruncatedToMinute 24 | 25 | -- Truncate to second 26 | SELECT DATETRUNC(second, @date) AS TruncatedToSecond 27 | 28 | 29 | --Truncating to Day 30 | ------------------- 31 | DECLARE @date datetime2 = '2024-10-08 13:45:30.123'; 32 | 33 | -- Traditional method 34 | SELECT CAST(CONVERT(date, @date) AS datetime) AS TruncatedToDay; 35 | 36 | -- Using DATETRUNC 37 | SELECT DATETRUNC(day, @date) AS TruncatedToDay; 38 | 39 | 40 | --Truncating to Month and Year 41 | ------------------------------ 42 | DECLARE @date datetime2 = '2024-10-08 13:45:30.123'; 43 | 44 | -- Truncating to Month 45 | -- Traditional method 46 | SELECT DATEADD(month, DATEDIFF(month, 0, @date), 0) AS TruncatedToMonth; 47 | 48 | -- Using DATETRUNC 49 | SELECT DATETRUNC(month, @date) AS TruncatedToMonth; 50 | 51 | -- Truncating to Year 52 | -- Traditional method 53 | SELECT DATEADD(year, DATEDIFF(year, 0, @date), 0) AS TruncatedToYear; 54 | 55 | -- Using DATETRUNC 56 | SELECT DATETRUNC(year, @date) AS TruncatedToYear; -------------------------------------------------------------------------------- /T-SQL_Enhancements_2022/4.LEAST and GREATEST.sql: -------------------------------------------------------------------------------- 1 | USE AdventureWorks2022 2 | GO 3 | 4 | 5 | --Syntax 6 | /* 7 | LEAST: Returns the smallest value from a list of expressions. 8 | 9 | LEAST ( 10 | expression1, 11 | expression2, 12 | ..., 13 | expressionN 14 | ) 15 | 16 | GREATEST: Returns the largest value from a list of expressions. 17 | 18 | GREATEST ( 19 | expression1, 20 | expression2, 21 | ..., 22 | expressionN 23 | ) 24 | */ 25 | 26 | --Tradtitional Methods 27 | SELECT 28 | CASE 29 | WHEN Column1 <= Column2 AND Column1 <= Column3 THEN Column1 30 | WHEN Column2 <= Column1 AND Column2 <= Column3 THEN Column2 31 | ELSE Column3 32 | END AS SmallestValue, 33 | 34 | CASE 35 | WHEN Column1 >= Column2 AND Column1 >= Column3 THEN Column1 36 | WHEN Column2 >= Column1 AND Column2 >= Column3 THEN Column2 37 | ELSE Column3 38 | END AS LargestValue 39 | FROM MyTable; 40 | 41 | --Using LEAST and GREATEST 42 | SELECT 43 | LEAST(Column1, Column2, Column3) AS SmallestValue, 44 | GREATEST(Column1, Column2, Column3) AS LargestValue 45 | FROM 46 | MyTable; 47 | 48 | -- Using LEAST to Compare Different Tax Rates 49 | SELECT 50 | SalesOrderID, 51 | LEAST(TaxAmt, Freight, SubTotal) AS SmallestAmount 52 | FROM Sales.SalesOrderHeader WITH (NOLOCK) 53 | WHERE SalesOrderID IN (43659, 43660, 43661); 54 | 55 | 56 | --Use GREATEST to Find the Maximum Bonus, Sick Leave, and Vacation Hours 57 | 58 | SELECT 59 | BusinessEntityID, 60 | GREATEST(VacationHours, SickLeaveHours, 10) AS MaxBenefit 61 | FROM 62 | HumanResources.Employee 63 | WHERE 64 | BusinessEntityID BETWEEN 1 AND 10; -------------------------------------------------------------------------------- /T-SQL_Enhancements_2022/5.STRING_SPLIT.sql: -------------------------------------------------------------------------------- 1 | USE AdventureWorks2022 2 | GO 3 | 4 | --Syntax: STRING_SPLIT (string , separator); 5 | --string: The string to be split. 6 | --separator: The character used to separate the string into parts. 7 | 8 | --Example: 9 | SELECT value FROM STRING_SPLIT('STRING_SPLIT,New,SQL,Server,2022,Enhancement', ',') 10 | 11 | --New Ordinal Enhancement 12 | 13 | --Syntax: STRING_SPLIT (string , separator [,enable_ordinal]); 14 | --enable_ordinal: A bit flag (0 or 1) that specifies whether to include the ordinal column in the output. 15 | --When set to 1, the result set includes both the value and the ordinal position of each element in the string. 16 | 17 | SELECT value, ordinal FROM STRING_SPLIT('STRING_SPLIT,New,SQL,Server,2022,Enhancement', ',', 1) -------------------------------------------------------------------------------- /T-SQL_Enhancements_2022/6.TRIM.sql: -------------------------------------------------------------------------------- 1 | USE AdventureWorks2022 2 | GO 3 | 4 | --In this example, the function removes spaces from both ends of the string, resulting in 5 | SELECT TRIM(' Trim example: with extra leading and trailing spaces ') AS TrimResult 6 | 7 | --As with SQL Server 2017, trimming spaces remains the default functionality. 8 | SELECT TRIM(' Naveen, C# Corner MVP! ') AS DefaultTrimResult 9 | 10 | --For example, if you want to remove specific punctuation marks or whitespace, you can use. 11 | SELECT TRIM('.,! ' FROM '...Naveen, C# Corner MVP!') AS NoiseCharTrimResult 12 | 13 | --In certain scenarios, it is beneficial to remove only leading characters. The LEADING keyword allows this precise control. 14 | SELECT TRIM(LEADING '.,! ' FROM '...Naveen, C# Corner MVP!!!') AS LeadingTrimResult 15 | 16 | --Similarly, if you need to remove trailing characters from a string, the TRAILING keyword comes into play. 17 | SELECT TRIM(TRAILING '.,! ' FROM '...Naveen, C# Corner MVP!!!') AS TrailingTrimResult 18 | 19 | --To emulate LTRIM, which removes leading spaces, you can do the following 20 | SELECT TRIM(LEADING ' ' FROM ' Hello, World! ') AS EmulateLTRIMResult 21 | SELECT TRIM(TRAILING ' ' FROM ' Hello, World! ') AS EmulateRTRIMResult -------------------------------------------------------------------------------- /T-SQL_Enhancements_2022/7.GENERATE_SERIES.sql: -------------------------------------------------------------------------------- 1 | USE AdventureWorks2022 2 | GO 3 | 4 | 5 | --Syntax: GENERATE_SERIES(start_value, stop_value [, step_value]) 6 | -- start_value: The beginning value of the series (required). 7 | -- stop_value: The ending value of the series (required). 8 | -- step_value: The increment between each successive value (optional). 9 | -- If not specified, the default is 1. 10 | 11 | --Generating a Series of Numbers 12 | 13 | SELECT value AS NumberSeries 14 | FROM GENERATE_SERIES(1, 10); 15 | -- In this example, the function generates a series of numbers from 1 to 10. 16 | 17 | SELECT value AS EvenNumbers 18 | FROM GENERATE_SERIES(2, 20, 2); 19 | -- You can customize the step value to generate a sequence that increments by a specific value. 20 | -- For instance, to generate a series of even numbers. 21 | 22 | --Generating Test Data 23 | SELECT value AS EmployeeID, 24 | 'Employee' + CAST(value AS VARCHAR(10)) AS EmployeeName 25 | FROM GENERATE_SERIES(1, 10); 26 | 27 | --Generating Date Ranges for Sales Reporting 28 | WITH DateSeries AS ( 29 | SELECT CAST(DATEADD(DAY, value, '2014-01-01') AS DATE) AS SaleDate 30 | FROM GENERATE_SERIES(0, 9) -- Generates dates from '2014-01-01' to '2014-01-10' 31 | ) 32 | SELECT ds.SaleDate, 33 | COALESCE(SUM(d.UnitPrice * d.OrderQty), 0) AS SalesAmount 34 | FROM DateSeries ds 35 | LEFT JOIN Sales.SalesOrderHeader s 36 | ON CAST(s.OrderDate AS DATE) = ds.SaleDate 37 | LEFT JOIN Sales.SalesOrderDetail d 38 | ON s.SalesOrderID = d.SalesOrderID 39 | GROUP BY ds.SaleDate 40 | ORDER BY ds.SaleDate; -------------------------------------------------------------------------------- /T-SQL_Enhancements_2022/8.WINDOWS Function.sql: -------------------------------------------------------------------------------- 1 | USE MyWork 2 | GO 3 | 4 | CREATE TABLE dbo.AccountTransactions ( 5 | AccountID INT, 6 | TransactionDate DATE, 7 | Amount DECIMAL(10, 2)); 8 | 9 | INSERT INTO dbo.AccountTransactions (AccountID, TransactionDate, Amount) 10 | VALUES 11 | (1, '2023-01-01', 100.00), 12 | (1, '2023-01-02', 150.00), 13 | (1, '2023-01-03', 200.00), 14 | (1, '2023-01-04', NULL), 15 | (1, '2023-01-05', 300.00), 16 | (2, '2023-01-01', 500.00), 17 | (2, '2023-01-02', 700.00), 18 | (2, '2023-01-03', NULL), 19 | (2, '2023-01-04', 800.00), 20 | (2, '2023-01-05', 900.00); 21 | 22 | 23 | 24 | --Using OVER with ORDER BY for Aggregate Functions - Running Total of Transactions by Account 25 | 26 | --The SUM function is paired with OVER (PARTITION BY AccountID ORDER BY TransactionDate). 27 | --For each row, it calculates a running total of the Amount column by partitioning the data by AccountID and ordering it by TransactionDate. 28 | SELECT 29 | AccountID, 30 | TransactionDate, 31 | Amount, 32 | SUM(Amount) OVER (PARTITION BY AccountID ORDER BY TransactionDate) AS RunningTotal 33 | FROM dbo.AccountTransactions 34 | ORDER BY AccountID, TransactionDate; 35 | -------------------------------------------------------------------------------------------------------------------------------------------------- 36 | 37 | --Sliding Aggregations with a Limit on Rows per Window -Three-Row Sliding Sum 38 | 39 | --The ROWS 2 PRECEDING clause limits the window to the current row and the previous two rows. 40 | --This is a rolling three-row sum, which helps in understanding recent trends in transaction amounts. 41 | 42 | SELECT 43 | AccountID, 44 | TransactionDate, 45 | Amount, 46 | SUM(Amount) OVER (PARTITION BY AccountID ORDER BY TransactionDate ROWS 2 PRECEDING) AS SlidingSum 47 | FROM dbo.AccountTransactions 48 | ORDER BY AccountID, TransactionDate; 49 | -------------------------------------------------------------------------------------------------------------------------------------------------- 50 | 51 | --Using the WINDOW Clause to Eliminate Code Duplication - Defining and Using a Window 52 | 53 | --The WINDOW clause defines a reusable window called w, which can then be applied to different aggregates, reducing code repetition and making modifications easier. 54 | 55 | SELECT 56 | AccountID, 57 | TransactionDate, 58 | Amount, 59 | SUM(Amount) OVER w AS RunningTotal, 60 | AVG(Amount) OVER w AS RollingAverage 61 | FROM dbo.AccountTransactions 62 | WINDOW w AS (PARTITION BY AccountID ORDER BY TransactionDate ROWS BETWEEN 2 PRECEDING AND CURRENT ROW) 63 | ORDER BY AccountID, TransactionDate; 64 | -------------------------------------------------------------------------------------------------------------------------------------------------- 65 | 66 | --Using IGNORE NULLS in FIRST_VALUE and LAST_VALUE Functions - Getting the Last Non-NULL Value per Account 67 | 68 | --Without IGNORE NULLS, the LAST_VALUE function would return a NULL value if the last row in the partition contained NULL. 69 | --With IGNORE NULLS, SQL Server skips over the NULL values and returns the most recent non-null value instead. 70 | 71 | SELECT 72 | AccountID, 73 | TransactionDate, 74 | Amount, 75 | LAST_VALUE(Amount) IGNORE NULLS OVER (PARTITION BY AccountID ORDER BY TransactionDate) AS LastNonNullAmount 76 | FROM dbo.AccountTransactions 77 | ORDER BY AccountID, TransactionDate; 78 | 79 | -------------------------------------------------------------------------------------------------------------------------------------------------- 80 | --Handling NULLs with the IGNORE NULLS Option for Aggregations - Average Transaction Amount Ignoring NULLs 81 | 82 | --With IGNORE NULLS, the calculation ignores rows where Amount is NULL, providing a more accurate average. 83 | 84 | SELECT 85 | AccountID, 86 | TransactionDate, 87 | Amount, 88 | SUM(Amount) OVER (PARTITION BY AccountID ORDER BY TransactionDate ROWS BETWEEN UNBOUNDED PRECEDING AND CURRENT ROW) / 89 | NULLIF(COUNT(Amount) OVER (PARTITION BY AccountID ORDER BY TransactionDate ROWS BETWEEN UNBOUNDED PRECEDING AND CURRENT ROW), 0) 90 | AS AverageAmount 91 | FROM dbo.AccountTransactions 92 | ORDER BY AccountID, TransactionDate; -------------------------------------------------------------------------------- /T-SQL_Enhancements_2022/9.BIT Function.sql: -------------------------------------------------------------------------------- 1 | USE AdventureWorks2022 2 | GO 3 | 4 | CREATE TABLE dbo.Employee ( 5 | EmployeeId int IDENTITY PRIMARY KEY, 6 | FirstName varchar(50), 7 | LastName varchar(50), 8 | AccessLevels tinyint, -- Store access levels or permissions across 8 single-bit values (0 or 1) in a single byte (0-255) 9 | ColorCode tinyint -- Store RGB color components in 3 bits (Red, Green, Blue) in a single byte (0-255) 10 | ); 11 | 12 | 13 | INSERT INTO dbo.Employee (FirstName, LastName, AccessLevels, ColorCode) VALUES 14 | ('Naveen', 'Kumar', 0x01, 0x07), 15 | ('Shaukat', 'Salim', 0x23, 0x16), 16 | ('Gaurav', 'Sharma', 0x3C, 0x3C), 17 | ('Pranav', 'Jujaray', 0x1A, 0x32), 18 | ('Mohan', 'B', 0xFF, 0xFF); 19 | 20 | 21 | SELECT 22 | FirstName, 23 | AccessLevels, 24 | AccessLevelCount = BIT_COUNT(AccessLevels) 25 | FROM dbo.Employee; 26 | 27 | SELECT 28 | FirstName, 29 | AccessLevels, 30 | ReadPermission = GET_BIT(AccessLevels, 0), 31 | WritePermission = GET_BIT(AccessLevels, 1), 32 | ExecutePermission = GET_BIT(AccessLevels, 2), 33 | DeletePermission = GET_BIT(AccessLevels, 3), 34 | AdminPermission = GET_BIT(AccessLevels, 4) 35 | FROM dbo.Employee; 36 | 37 | 38 | SELECT 39 | FirstName, 40 | ColorCode, 41 | RedComponent = RIGHT_SHIFT(ColorCode, 6), 42 | GreenComponent = (ColorCode & 0x30) >> 4, 43 | BlueComponent = ColorCode & 0x0F 44 | FROM dbo.Employee; 45 | -------------------------------------------------------------------------------- /TEMPDB_Query/1.TEMPDB_Query_Exec_Plan.sql: -------------------------------------------------------------------------------- 1 | /* Script to identify the queries using tempdb and their exection plan */ 2 | SELECT 3 | t1.session_id 4 | , t1.request_id 5 | , task_alloc_GB = CAST((t1.task_alloc_pages * 8./1024./1024.) AS NUMERIC(10,1)) 6 | , task_dealloc_GB = CAST((t1.task_dealloc_pages * 8./1024./1024.) AS NUMERIC(10,1)) 7 | , host= CASE WHEN t1.session_id <= 50 then 'SYS' else s1.host_name end 8 | , s1.login_name 9 | , s1.status 10 | , s1.last_request_start_time 11 | , s1.last_request_end_time 12 | , s1.row_count 13 | , s1.transaction_isolation_level 14 | , query_text= 15 | COALESCE((SELECT SUBSTRING(text, t2.statement_start_offset/2 + 1, 16 | (CASE WHEN statement_end_offset = -1 17 | THEN LEN(CONVERT(nvarchar(MAX),text)) * 2 18 | ELSE statement_end_offset 19 | END - t2.statement_start_offset)/2) 20 | FROM sys.dm_exec_sql_text(t2.sql_handle)) , 'Not currently executing') 21 | , query_plan=(SELECT query_plan FROM sys.dm_exec_query_plan(t2.plan_handle)) 22 | FROM 23 | (SELECT session_id, request_id 24 | , task_alloc_pages=SUM(internal_objects_alloc_page_count + user_objects_alloc_page_count) 25 | , task_dealloc_pages = SUM (internal_objects_dealloc_page_count + user_objects_dealloc_page_count) 26 | FROM sys.dm_db_task_space_usage 27 | GROUP BY session_id, request_id) AS t1 28 | LEFT JOIN sys.dm_exec_requests AS t2 ON 29 | t1.session_id = t2.session_id 30 | and t1.request_id = t2.request_id 31 | LEFT JOIN sys.dm_exec_sessions AS s1 ON 32 | t1.session_id=s1.session_id 33 | WHERE 34 | t1.session_id > 50 -- ignore system unless you suspect there's a problem there 35 | and t1.session_id <> @@SPID -- ignore this request itself 36 | ORDER BY t1.task_alloc_pages DESC; 37 | GO -------------------------------------------------------------------------------- /TEMPDB_Query/2.TEMPDB_Cleanup.sql: -------------------------------------------------------------------------------- 1 | --Find oldest transaction 2 | DBCC OPENTRAN 3 | 4 | -- Get input buffer for a SPID 5 | DBCC INPUTBUFFER(115) -- Replace the SPID number from above 6 | 7 | --Get tempdb files and available space in MB 8 | USE [Tempdb] 9 | GO 10 | SELECT 11 | name AS 'File Name', 12 | physical_name AS 'Physical Name', 13 | size/128 AS 'Total Size in MB', 14 | size/128.0 - CAST(FILEPROPERTY(name, 'SpaceUsed') AS int)/128.0 AS 'Available Space In MB', 15 | * 16 | FROM sys.database_files; 17 | 18 | --Shrink file by TRUNCATEONLY 19 | USE [tempdb] 20 | GO 21 | DBCC SHRINKFILE (N'temp2' , 0, TRUNCATEONLY) 22 | GO 23 | 24 | USE [tempdb] 25 | GO 26 | DBCC SHRINKFILE (N'tempdev' , 1024) 27 | GO 28 | 29 | USE [tempdb] 30 | GO 31 | CHECKPOINT 32 | 33 | USE tempdb 34 | GO 35 | 36 | SELECT name, size 37 | FROM sys.master_files 38 | WHERE database_id = DB_ID(N'tempdb'); 39 | GO 40 | 41 | DBCC FREEPROCCACHE -- clean cache 42 | DBCC DROPCLEANBUFFERS -- clean buffers 43 | DBCC FREESYSTEMCACHE ('ALL') -- clean system cache 44 | DBCC FREESESSIONCACHE -- clean session cache 45 | DBCC SHRINKDATABASE(tempdb, 10); -- shrink tempdb 46 | 47 | --Update the tempdb filles 48 | DBCC SHRINKFILE ('tempdev') -- shrink default db file 49 | DBCC SHRINKFILE ('templog') -- shrink db file tempdev 50 | DBCC SHRINKFILE ('temp1') -- shrink db file tempdev1 51 | DBCC SHRINKFILE ('temp2') -- shrink db file tempdev2 52 | DBCC SHRINKFILE ('templog1') -- shrink log file 53 | DBCC SHRINKFILE ('tempdev2') -- shrink log file 54 | 55 | GO -------------------------------------------------------------------------------- /TEMPDB_Query/3.TEMPDB_Usage.sql: -------------------------------------------------------------------------------- 1 | /****************************************************************************************************** 2 | Query returns who is consuming the TEMP DB 3 | ******************************************************************************************************/ 4 | 5 | SELECT 6 | st.dbid AS QueryExecutionContextDBID, 7 | DB_NAME(st.dbid) AS QueryExecContextDBNAME, 8 | st.objectid AS ModuleObjectId, 9 | SUBSTRING(st.TEXT, 10 | dmv_er.statement_start_offset/2 + 1, 11 | (CASE WHEN dmv_er.statement_end_offset = -1 12 | THEN LEN(CONVERT(NVARCHAR(MAX),st.TEXT)) * 2 13 | ELSE dmv_er.statement_end_offset 14 | END - dmv_er.statement_start_offset)/2) AS Query_Text, 15 | dmv_tsu.session_id , 16 | dmv_tsu.request_id, 17 | dmv_tsu.exec_context_id, 18 | (dmv_tsu.user_objects_alloc_page_count - dmv_tsu.user_objects_dealloc_page_count) AS OutStanding_user_objects_page_counts, 19 | (dmv_tsu.internal_objects_alloc_page_count - dmv_tsu.internal_objects_dealloc_page_count) AS OutStanding_internal_objects_page_counts, 20 | dmv_er.start_time, 21 | dmv_er.command, 22 | dmv_er.open_transaction_count, 23 | dmv_er.percent_complete, 24 | dmv_er.estimated_completion_time, 25 | dmv_er.cpu_time, 26 | dmv_er.total_elapsed_time, 27 | dmv_er.reads,dmv_er.writes, 28 | dmv_er.logical_reads, 29 | dmv_er.granted_query_memory, 30 | dmv_es.HOST_NAME, 31 | dmv_es.login_name, 32 | dmv_es.program_name 33 | FROM sys.dm_db_task_space_usage dmv_tsu 34 | INNER JOIN sys.dm_exec_requests dmv_er 35 | ON dmv_tsu.session_id = dmv_er.session_id AND dmv_tsu.request_id = dmv_er.request_id 36 | INNER JOIN sys.dm_exec_sessions dmv_es 37 | ON dmv_tsu.session_id = dmv_es.session_id 38 | CROSS APPLY sys.dm_exec_sql_text(dmv_er.sql_handle) st 39 | WHERE (dmv_tsu.internal_objects_alloc_page_count + dmv_tsu.user_objects_alloc_page_count) > 0 40 | ORDER BY (dmv_tsu.user_objects_alloc_page_count - dmv_tsu.user_objects_dealloc_page_count) + (dmv_tsu.internal_objects_alloc_page_count - dmv_tsu.internal_objects_dealloc_page_count) DESC --------------------------------------------------------------------------------