CREATE TABLE Table1 ( Id INT NOT NULL , SomeDate datetime NULL CONSTRAINT [PK_Table1] PRIMARY KEY CLUSTERED ( Id ASC ) )
-- Combining an INSERT with a SELECT. INSERT Table1 ( Col1 , Col2 , Col3 ) SELECT Table2.Col1 , Table2.Col2 , Table2.Col3 FROM Table2 -- INSERTing multiple rows. INSERT INTO Table1 (Col1, Col2, Col3) VALUES (Data1, Data2, Data3) , (Data1, Data2, Data3)
-- Combining an UPDATE with a SELECT. UPDATE Table1 SET Table1.Col1 = Table2.Col1 , Table1.Col2 = Table2.Col2 FROM Table1 INNER JOIN Table2 ON Table2.Id = Table1.Id
-- Combining an UPDATE with a JOIN. DELETE Table1 FROM Table1 INNER JOIN Table2 ON Table2.Id = Table1.Id
SELECT BestEmployee.Name FROM ( SELECT TOP 100 * FROM Employee ORDER BY Employee.Sales DESC ) AS BestEmployee ORDER BY BestEmployee.Name
-- Untested code. WITH BestEmployee_CTE AS ( SELECT TOP 100 * FROM Employee ORDER BY Employee.Sales DESC ) SELECT BestEmployee.Name FROM BestEmployee_CTE
-- Use *only* if a nested SELECT or CTE won't do the job. DECLARE @SpecialEmployees TABLE ( EmployeeID INT ) INSERT @SpecialEmployees (EmployeeID) SELECT Employee.EmployeeID FROM Employee
DECLARE @TargetTable VARCHAR(MAX) = 'Sale' DECLARE @maxExpansions INT = 600 DECLARE @FamilyTree TABLE ( ObjectId INT NOT NULL , TableName VARCHAR(MAX) NOT NULL , IsExpanded BIT NOT NULL , [Path] VARCHAR(MAX) NOT NULL ) INSERT @FamilyTree (ObjectId, TableName, IsExpanded, [Path]) SELECT TABLES.object_id , TABLES.[name] , 0 , TABLES.[name] FROM sys.tables WHERE sys.tables.[name] = @TargetTable DECLARE @currentObjectId INT DECLARE @currentExpansion INT = 0 SELECT TOP 1 @currentObjectId = [@FamilyTree].ObjectId FROM @FamilyTree WHERE [@FamilyTree].IsExpanded = 0 WHILE @currentObjectId IS NOT NULL AND @currentExpansion < @maxExpansions BEGIN INSERT @FamilyTree (ObjectId, TableName, IsExpanded, [Path]) SELECT DISTINCT ChildTable.object_id , ChildTable.[name] , 0 , CONCAT ([@FamilyTree].[Path], ' > ', ChildTable.[name]) FROM @FamilyTree JOIN sys.foreign_keys ForeignKey ON ForeignKey.parent_object_id = [@FamilyTree].ObjectId JOIN sys.tables ChildTable ON ChildTable.object_id = ForeignKey.referenced_object_id WHERE [@FamilyTree].ObjectId = @currentObjectId UPDATE @FamilyTree SET [@FamilyTree].IsExpanded = 1 WHERE [@FamilyTree].ObjectId = @currentObjectId SELECT TOP 1 @currentObjectId = [@FamilyTree].ObjectId FROM @FamilyTree WHERE [@FamilyTree].IsExpanded = 0 SELECT @currentExpansion = @currentExpansion + 1 END SELECT DISTINCT * , CONCAT( 'DELETE [' , [@FamilyTree].TableName , '] -- ' , [@FamilyTree].[Path] ) FROM @FamilyTree ORDER BY [@FamilyTree].[Path] DESC
-- Doesn't copy keys or constraints. CREATE TABLE NewTable AS SELECT * FROM SourceTable -- Omit, if data is also to be copied. WHERE 1=2;
ALTER TABLE TABLE_NAME ADD Column_Name INT NULL;
IF COL_LENGTH('Table_Name','Column_Name') IS NULL BEGIN ALTER TABLE TABLE_NAME ADD Column_Name INT NULL; END
EXEC sp_rename 'Categories.Active', 'Active_Old', 'COLUMN'
If you want to preserve permissions:
IF OBJECT_ID('StoredProcedure_Name') IS NULL EXEC ('CREATE PROCEDURE StoredProcedure_Name AS SELECT 1') GO ALTER PROCEDURE StoredProcedure_Name ( ...
If you are happy to blow away permissions:
IF OBJECT_ID('StoredProcedure_Name', 'P') IS NOT NULL DROP PROC StoredProcedure_Name GO CREATE PROCEDURE StoredProcedure_Name ( ...
SELECT * FROM sys.dm_exec_describe_first_result_set( N'EXEC SomeStoredProcedure 1234', NULL, 0);
-- Determine the default collation for the server. SELECT serverproperty('collation') -- Convert a varchar to a specific collation. SELECT CAST('abc' AS VARCHAR(5)) COLLATE Latin1_General_CI_AS
BACKUP DATABASE SourceDatabase TO DISK = 'E:\Backups\20150609 SourceDatabase.bak' WITH COPY_ONLY, INIT CREATE DATABASE NewDatabase -- Use the LogicalName column to populate the MOVE clause of the RESTORE DATABASE command. RESTORE FILELISTONLY FROM DISK = 'E:\Backups\20150609 SourceDatabase.bak' WITH FILE = 1 -- Use the physical_name column to populate the TO clause of the RESTORE DATABASE command. SELECT master_files.physical_name FROM master.sys.databases JOIN master.sys.master_files ON master_files.database_id = DATABASES.database_id WHERE DATABASES.name = 'NewDatabase' RESTORE DATABASE NewDatabase FROM DISK = 'E:\Backups\20150609 SourceDatabase.bak' WITH REPLACE , MOVE 'SourceDatabase' TO N'E:\Program Files\Microsoft SQL Server\MSSQL11.MSSQLSERVER\MSSQL\DATA\NewDatabase.mdf' , MOVE 'SourceDatabase_log' TO N'E:\Program Files\Microsoft SQL Server\MSSQL11.MSSQLSERVER\MSSQL\DATA\NewDatabase_log.ldf' -- Compare the databases. No results = no differences. SELECT * FROM SourceDatabase.sys.objects SourceObjects FULL JOIN NewDatabase.sys.objects NewObjects ON NewObjects.object_id = SourceObjects.object_id WHERE SourceObjects.object_id IS NULL OR NewObjects.object_id IS NULL
Install SqlPackage:
dotnet tool install -g microsoft.sqlpackage
Export .backpac. Only add the Encrypt=False
for local exports.
SqlPackage /Action:Export /TargetFile:"D:\Dev\BucketsOfFundsSQL\$((Get-Date).ToString("yyyyMMdd")) Buckets.bacpac" /SourceConnectionString:"Integrated Security=SSPI;Persist Security Info=False;Encrypt=False;Initial Catalog=Buckets;Data Source=."
ALTER DATABASE DatabaseName SET SINGLE_USER WITH ROLLBACK IMMEDIATE GO -- Do this straight away, because it sucks if a database is left in single user mode. ALTER DATABASE DatabaseName SET MULTI_USER GO
-- Find a table in all databases. sp_msforeachdb @command1='USE ?;SELECT DB_NAME() AS [Database], * FROM sys.Tables WHERE name LIKE ''TableName'''
-- Find a table column in all databases. sp_msforeachdb @command1='USE ?;SELECT DB_NAME() AS [Database], t.name AS [Table], * FROM sys.Columns c JOIN sys.Tables t ON t.object_id = c.object_id WHERE c.name LIKE ''ColumnName'''
-- No results = no differences. This is only suitable for databases that have been duplicated *exactly*. SELECT * FROM SourceDatabase.sys.objects SourceObjects FULL JOIN TargetDatabase.sys.objects TargetDatabase ON TargetDatabase.object_id = SourceObjects.object_id WHERE SourceObjects.object_id IS NULL OR TargetDatabase.object_id IS NULL
SELECT * FROM Foo INNER JOIN History MostRecentHistory ON MostRecentHistory.FooId = Foo.Id LEFT JOIN History AllHistory ON AllHistory.FooId = MostRecentHistory.FooId AND AllHistory.LastUpdateOn > MostRecentHistory.LastUpdateOn WHERE AllHistory.Id IS NULL -- If the Foo table may not have history and all results are still required: SELECT * FROM Foo LEFT JOIN History MostRecentHistory ON MostRecentHistory.FooId = Foo.Id LEFT JOIN History AllHistory ON AllHistory.FooId = MostRecentHistory.FooId AND AllHistory.LastUpdateOn > MostRecentHistory.LastUpdateOn WHERE AllHistory.Id IS NULL
Use a Nested SELECT Statement or a Common Table Expression instead!
DECLARE @Results TABLE ( BananaId INT , BananaName VARCHAR(MAX) )
Use a Nested SELECT Statement or a Common Table Expression instead!
DECLARE @Results TABLE ( BananaId INT , BananaName VARCHAR(MAX) ) INSERT INTO @Results EXEC GetRipeBananas
Can do this, but it will only show which tables reference the specified table, not what tables the specified table references:
sp_fkeys TableName
Better to do this, which lists all foreign key relationships and lots of other information as well:
sp_help TableName
SELECT ForeignKey.[name] ForeignKey , PrimaryTable.[name] PrimaryTable , PrimaryColumn.[name] PrimaryColumn , ForeignTable.[name] ForeignTable , ForeignColumn.[name] ForeignColumn FROM sys.foreign_key_columns ForeignKeyColumn JOIN sys.foreign_keys ForeignKey ON ForeignKey.object_id = ForeignKeyColumn.constraint_object_id JOIN sys.columns PrimaryColumn ON PrimaryColumn.object_id = ForeignKeyColumn.referenced_object_id AND PrimaryColumn.column_id = ForeignKeyColumn.referenced_column_id JOIN sys.tables PrimaryTable ON PrimaryTable.object_id = ForeignKeyColumn.referenced_object_id JOIN sys.columns ForeignColumn ON ForeignColumn.object_id = ForeignKeyColumn.parent_object_id AND ForeignColumn.column_id = ForeignKeyColumn.parent_column_id JOIN sys.tables ForeignTable ON ForeignTable.object_id = ForeignKeyColumn.parent_object_id ORDER BY PrimaryTable.[name] , PrimaryColumn.[name] , ForeignTable.[name] , ForeignColumn.[name]
SELECT [Schema].[name] SchemaName , [TABLE].[name] TableName , [COLUMN].[name] ColumnName , [ColumnType].[name] ColumnType , [COLUMN].max_length [MaxLength] , [COLUMN].[PRECISION] [PRECISION] , [COLUMN].is_nullable NULLABLE FROM sys.tables [TABLE] JOIN sys.schemas [Schema] ON [Schema].schema_id = [TABLE].schema_id JOIN sys.columns [COLUMN] ON [COLUMN].object_id = [TABLE].object_id JOIN sys.types [ColumnType] ON [ColumnType].system_type_id = [COLUMN].system_type_id ORDER BY [Schema].[name] , [TABLE].[name] , [COLUMN].[name]
DECLARE @searchText NVARCHAR(20) = N'Foo'; DECLARE @SQL NVARCHAR(MAX) = N''; SELECT @SQL = @SQL + CONCAT( 'SELECT ''' , [TABLE].[name] , ''' AS [Table], ''' , [COLUMN].[name] , ''' AS [Column], [' , [TABLE].[name] , '].[' , [COLUMN].[name] , '] AS [Data] FROM ' , [TABLE].[name] , ' WHERE [' , [TABLE].[name] , '].[' , [COLUMN].[name] , '] LIKE ''%' , @searchText , '%''' , CHAR(13) + CHAR(10) , 'UNION ALL' , CHAR(13) + CHAR(10) ) FROM sys.columns AS [COLUMN] JOIN sys.tables AS [TABLE] ON [TABLE].object_id = [COLUMN].object_id JOIN sys.systypes AS ColumnType ON ColumnType.xtype = [COLUMN].system_type_id WHERE [ColumnType].[name] IN ('nchar', 'ntext', 'nvarchar', 'text', 'varchar') ORDER BY [TABLE].[name] , [COLUMN].[name] SELECT @SQL = SUBSTRING(@SQL,1, LEN(@SQL) - 11); EXEC (@SQL)
UNION ALL
.-- DECLARE @searchText NVARCHAR(100) = N'%foo%'; SELECT CONCAT( 'SELECT ''' , [TABLE].[name] , ''' AS [Table], ''' , [COLUMN].[name] , ''' AS [Column], [' , [TABLE].[name] , '].[' , [COLUMN].[name] , '] COLLATE ' , CONVERT(NVARCHAR, serverproperty('collation')) , ' AS [Data] FROM [' , [TABLE].[name] , '] WHERE [' , [TABLE].[name] , '].[' , [COLUMN].[name] , '] LIKE @searchText UNION ALL' ) FROM sys.columns AS [COLUMN] JOIN sys.tables AS [TABLE] ON [TABLE].object_id = [COLUMN].object_id JOIN sys.systypes AS ColumnType ON ColumnType.xtype = [COLUMN].system_type_id JOIN sys.schemas AS [Schema] ON [Schema].schema_id = [TABLE].schema_id WHERE [ColumnType].[name] IN ('nchar', 'ntext', 'nvarchar', 'text', 'varchar') AND [TABLE].is_ms_shipped = 0 AND [Schema].[name] = 'dbo' ORDER BY [TABLE].[name] , [COLUMN].[name]
SELECT ABS(CAST(CAST(NEWID() AS VARBINARY) AS INT)) AS RandomNumber SELECT LEFT(CAST(NEWID() AS VARCHAR(100)), 6) AS RandomString -- Semi-random, good for randomish sorting, returns varbinary(8000) SELECT HashBytes('MD5', CONCAT('Seed', TABLE.TableId)) -- Same thing, but returns varchar(32) SELECT CONVERT(VARCHAR(32), HashBytes('MD5', CONCAT('Seed', TABLE.TableId)), 2)
EXEC sys.xp_fixeddrives
-- Just for general info EXEC master.dbo.xp_fileexist N'\\PVW-ENT-SQL32\Backups\SMS.bak' -- Part of a script that needs to make a decision. DECLARE @RESULT INT EXEC master.dbo.xp_fileexist N'\\PVW-ENT-SQL32\Backups\SMS.bak', @RESULT OUTPUT IF @RESULT = 1 PRINT 'File exists.' ELSE PRINT 'File does not exist.'
EXEC Master.dbo.xp_DirTree 'C:',1,1
-- Replace username with the actual username. USE DATABASE EXEC sp_change_users_login 'report' EXEC sp_change_users_login 'auto_fix', 'CIPLogin' -- This definitely works. -- Or try: EXEC sp_change_users_login @Action = 'auto_fix', @UserNamePattern = 'User', @Password = 'Password' EXEC sp_change_users_login 'update_one', username, username -- Quantate USE QuantateAdministration EXEC sp_change_users_login 'update_one', 'QuantateSysAdmin', 'Quantate_Login' -- CIP USE CIP EXEC sp_change_users_login 'update_one', 'CIPUser', 'CIPLogin' -- NGA Provisioning USE NextGenProvDB EXEC sp_change_users_login 'update_one', 'NextGenUser', 'NextGenLogin' -- General. EXEC sp_change_users_login 'update_one', 'DBUser', 'ServerUser' -- Server -> Security -> Logins -> *ServerUser* -> Right click -> Properties -- User Mapping -> Find correct database, value in User col = *DBUser*
SELECT TOP 100 * FROM OpenQuery (LinkedServerName, 'SELECT * FROM Users')
This is particularly useful when the database is on Azure.
-- Create the Login. -- The CHECK_EXPIRATION and CHECK_POLICY options relate to the password. Switch them off for a service or application type login. CREATE LOGIN [OrchardUser] WITH PASSWORD=N'XXXXXXX', DEFAULT_DATABASE=[master], CHECK_EXPIRATION=OFF, CHECK_POLICY=OFF GO -- Create the User. CREATE USER [OrchardUser] FOR LOGIN [OrchardUser] WITH DEFAULT_SCHEMA=[dbo] GO -- Grant a role. EXEC sp_addrolemember N'db_owner', N'OrchardUser'
Generates SQL commands to drop everything in the database. Be careful you nuke the correct database…
USE [DATABASE] SELECT 'DROP PROCEDURE ' + [Schema].name + '.' + StoredProcedure.name AS SqlCommand , 10 AS SortOrder FROM sys.objects StoredProcedure JOIN sys.schemas [Schema] ON [Schema].schema_id = StoredProcedure.schema_id WHERE StoredProcedure.TYPE = 'P' UNION SELECT 'DROP VIEW ' + sys.objects.name , 20 FROM sys.objects WHERE sys.objects.TYPE = 'V' UNION SELECT 'ALTER TABLE ' + [ParentTable].Name + ' DROP CONSTRAINT [' + [ForeignKey].name + ']' , 30 FROM sys.objects [ForeignKey] JOIN sys.objects [ParentTable] ON [ParentTable].object_id = [ForeignKey].parent_object_id WHERE [ForeignKey].TYPE = 'F' UNION SELECT 'DROP TABLE ' + sys.objects.name , 40 FROM sys.objects WHERE sys.objects.TYPE = 'U' ORDER BY SortOrder
EXEC sp_who -- Find the spid of the connect that is connected to the database. KILL 56 ALTER DATABASE [DatebaseName] SET MULTI_USER
If only one result set is returned:
using (SqlConnection connection = new SqlConnection("Data Source=...")) { connection.Open(); using (SqlCommand command = new SqlCommand("StoredProcedureName", connection)) { command.CommandType = CommandType.StoredProcedure; command.CommandTimeout = 300; using (SqlDataReader reader = command.ExecuteReader()) { while (reader.Read()) { for (int i = 0; i < reader.FieldCount; i++) { string fieldName = reader.GetName(i); // Note that values must be accessed by the column index and can not be accessed directly by field name. string fieldValue = reader.GetValue(i); Console.WriteLine("{0}: {1}", fieldName, fieldValue); } } reader.Close(); } } }
If multiple result sets are returned:
using (SqlConnection connection = new SqlConnection("Data Source=...")) { connection.Open(); using (SqlCommand command = new SqlCommand("StoredProcedureName", connection)) { command.CommandType = CommandType.StoredProcedure; command.CommandTimeout = 300; using (SqlDataReader reader = command.ExecuteReader()) { do { while (reader.Read()) { for (int i = 0; i < reader.FieldCount; i++) { string fieldName = reader.GetName(i); // Note that values must be accessed by the column index and can not be accessed directly by field name. string fieldValue = reader.GetValue(i); Console.WriteLine("{0}: {1}", fieldName, fieldValue); } } // Move to the next set of results. } while (reader.NextResult()); reader.Close(); } } }