├── .vs └── slnx.sqlite ├── LICENSE ├── README.md ├── Stored_Procedures ├── Create_Type_ContactNote.sql ├── Create_Type_Driving_License.sql ├── Insert _Contact _Notes_Stored_Procedure_CSV_Version_While_Loop.sql ├── Insert _Contact_Notes_Stored_Procedure_Type_With_Table_Update_Script.sql ├── Insert_Contact_Address_Stored_Procedure.sql ├── Insert_Contact_Notes_Stored_Procedure_CSV_Version.sql ├── Insert_Contact_Role_Stored_Procedure.sql ├── Insert_Contact_Stored Procedure.sql └── Select_Contacts_Stored _Procedure.sql ├── Triger_Functions ├── DDL.sql ├── DELETE_AFTER Examples.sql ├── INSERT_AFTER.sql ├── INSERT_INSTEAD_OF.sql ├── Local_Authentication_Triggers.sql ├── Simple_Function _Samples.sql ├── Trigger_Order.sql └── UPDATE_AFTER.sql └── src └── contactdb.sql /.vs/slnx.sqlite: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/Burakkylmz/Programming_SQL_Server_Database/5540ff82dc23522efaaf7cf19a31cfdeb6d9c40c/.vs/slnx.sqlite -------------------------------------------------------------------------------- /LICENSE: -------------------------------------------------------------------------------- 1 | MIT License 2 | 3 | Copyright (c) 2021 Burak 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 | -------------------------------------------------------------------------------- /README.md: -------------------------------------------------------------------------------- 1 | # SQL_Server 2 | 3 | ## Microsoft SQL Server is a relational database management system developed by Microsoft. As a database server, it is a software product with the primary function of storing and retrieving data as requested by other software applications—which may run either on the same computer or on another computer across a network. 4 | 5 | ### [Stored Procedures](https://github.com/Burakkylmz/SQL_Server/tree/master/Stored_Procedures) 6 | 7 | Most of the popular relational database systems, SQL Server, Oracle, MySQL and the like, support stored procedures. A stored procedure is nothing more than a piece of code that performs some repetitive set of actions. It performs a particular task by executing a set of actions or queries against the database. The code for the stored procedure is stored in the database and can be executed at any time. Stored procedures are typically used to insert your records into one of more tables, update or delete data from tables, and to generate reports via the SELECT statement. It's actually possible for a stored procedure to do more than one thing. 8 | 9 | > If you want to try the stored procedure examples, first run the contactdb.sql scripts under the src folder in SQL Server to create the sample database. 10 | 11 | ### [Trigers & Functions](https://github.com/Burakkylmz/Programming_SQL_Server_Database/tree/master/Triger_Functions) 12 | 13 | ##### What is a DML Trigger? 14 | 15 | DML stands for data manipulation language, and it's that vocabulary of standard T-SQL commands that you already know that attempt to retrieve data, modify data, or manipulate it, things like SELECT and INSERT and UPDATE and DELETE. Data in a relational database is stored within tables, a concept we're used to, and DML triggers watch for data manipulation events. So inserting, updating, and deleted. 16 | 17 | ##### After & Instead of Triggers 18 | 19 | Within SQL Server, there are two kinds of triggers, INSTEAD OF and AFTER triggers. In almost every way, they really are the same. The only difference is where and when they do their work, but they're working on the same data. So first, let's review the similarities and then look at their differences. Both INSTEAD OF and AFTER triggers have access to inserted and deleted data, and both execute within the DML transaction that began this event, so the UPDATE statement, the INSERT statement, whatever that was. The real difference comes in these last two points, which speaks to the difference of when the data is actually passed to the trigger and the responsibility of the trigger to do something with that data. In an AFTER trigger, all the constraints have passed, and the data that's passed to the trigger is already considered good. 20 | 21 | 22 | -------------------------------------------------------------------------------- /Stored_Procedures/Create_Type_ContactNote.sql: -------------------------------------------------------------------------------- 1 | USE Contacts; 2 | 3 | DROP TYPE IF EXISTS dbo.ContactNote; 4 | 5 | GO 6 | 7 | CREATE TYPE dbo.ContactNote 8 | AS TABLE 9 | ( 10 | Note VARCHAR(MAX) NOT NULL 11 | ); -------------------------------------------------------------------------------- /Stored_Procedures/Create_Type_Driving_License.sql: -------------------------------------------------------------------------------- 1 | USE Contacts; 2 | 3 | GO 4 | 5 | CREATE TYPE dbo.DrivingLicense 6 | FROM CHAR(16) NOT NULL; 7 | 8 | DROP TYPE dbo.DrivingLicense; 9 | -------------------------------------------------------------------------------- /Stored_Procedures/Insert _Contact _Notes_Stored_Procedure_CSV_Version_While_Loop.sql: -------------------------------------------------------------------------------- 1 | USE Contacts; 2 | 3 | IF EXISTS(SELECT 1 FROM sys.procedures WHERE [name] = 'InsertContactNotes') 4 | BEGIN; 5 | DROP PROCEDURE dbo.InsertContactNotes; 6 | END; 7 | 8 | GO 9 | 10 | CREATE PROCEDURE dbo.InsertContactNotes 11 | ( 12 | @ContactId INT, 13 | @Notes VARCHAR(MAX) 14 | ) 15 | AS 16 | BEGIN; 17 | 18 | DECLARE @NoteTable TABLE (Note VARCHAR(MAX)); 19 | DECLARE @NoteValue VARCHAR(MAX); 20 | 21 | INSERT INTO @NoteTable (Note) 22 | SELECT value 23 | FROM STRING_SPLIT(@Notes, ','); 24 | 25 | WHILE ((SELECT COUNT(*) FROM @NoteTable) > 0) 26 | BEGIN; 27 | 28 | SELECT TOP 1 @NoteValue = Note FROM @NoteTable; 29 | 30 | INSERT INTO dbo.ContactNotes (ContactId, Notes) 31 | VALUES (@ContactId, @NoteValue); 32 | 33 | DELETE FROM @NoteTable WHERE Note = @NoteValue; 34 | 35 | END; 36 | 37 | SELECT * FROM dbo.ContactNotes 38 | WHERE ContactId = @ContactId 39 | ORDER BY NoteId DESC; 40 | 41 | END; 42 | -------------------------------------------------------------------------------- /Stored_Procedures/Insert _Contact_Notes_Stored_Procedure_Type_With_Table_Update_Script.sql: -------------------------------------------------------------------------------- 1 | USE Contacts; 2 | 3 | DROP PROCEDURE IF EXISTS dbo.InsertContactNotes; 4 | 5 | GO 6 | 7 | CREATE PROCEDURE dbo.InsertContactNotes 8 | ( 9 | @ContactId INT, 10 | @Notes ContactNote READONLY 11 | ) 12 | AS 13 | BEGIN; 14 | 15 | DECLARE @TempNotes ContactNote; 16 | 17 | INSERT INTO @TempNotes (Note) 18 | SELECT Note FROM @Notes; 19 | 20 | UPDATE @TempNotes SET Note = 'Pre: ' + Note; 21 | 22 | INSERT INTO dbo.ContactNotes (ContactId, Notes) 23 | SELECT @ContactId, Note 24 | FROM @Notes; 25 | 26 | SELECT * FROM dbo.ContactNotes 27 | WHERE ContactId = @ContactId 28 | ORDER BY NoteId DESC; 29 | 30 | END; 31 | 32 | --test script 33 | 34 | DECLARE @TempNotes ContactNote; 35 | 36 | INSERT INTO @TempNotes (Note) 37 | VALUES 38 | ('Hi, Peter called.'), 39 | ('Quick note to let you know Jo wants you to ring her. She rang at 14:30.'), 40 | ('Terri asked about the quote, I have asked her to ring back tomorrow.'); 41 | 42 | EXEC dbo.InsertContactNotes 43 | @ContactId = 23, 44 | @Notes = @TempNotes; 45 | -------------------------------------------------------------------------------- /Stored_Procedures/Insert_Contact_Address_Stored_Procedure.sql: -------------------------------------------------------------------------------- 1 | USE Contacts; 2 | 3 | DROP PROCEDURE IF EXISTS dbo.InsertContactAddress; 4 | 5 | GO 6 | 7 | CREATE PROCEDURE dbo.InsertContactAddress 8 | ( 9 | @ContactId INT, 10 | @HouseNumber VARCHAR(200), 11 | @Street VARCHAR(200), 12 | @City VARCHAR(200), 13 | @Postcode VARCHAR(20) 14 | ) 15 | AS 16 | BEGIN; 17 | 18 | SET NOCOUNT ON; 19 | 20 | DECLARE @AddressId INT; 21 | 22 | SELECT @Street = UPPER(LEFT(@Street, 1)) + LOWER(RIGHT(@Street, LEN(@Street) -1)); 23 | SELECT @City = UPPER(LEFT(@City, 1)) + LOWER(RIGHT(@City, LEN(@City) - 1)); 24 | 25 | INSERT INTO dbo.ContactAddresses (ContactId, HouseNumber, Street, City, Postcode) 26 | VALUES (@ContactId, @HouseNumber, @Street, @City, @Postcode); 27 | 28 | SELECT @AddressId = SCOPE_IDENTITY(); 29 | 30 | SELECT ContactId, AddressId, HouseNumber, Street, City, Postcode 31 | FROM dbo.ContactAddresses 32 | WHERE ContactId = @ContactId; 33 | 34 | SET NOCOUNT OFF; 35 | 36 | END; 37 | 38 | --test script 39 | 40 | EXEC dbo.InsertContactAddress 41 | @ContactId = 24, 42 | @HouseNumber = '10', 43 | @Street = 'Downing Street', 44 | @City = 'London', 45 | @Postcode = 'SW1 2AA'; -------------------------------------------------------------------------------- /Stored_Procedures/Insert_Contact_Notes_Stored_Procedure_CSV_Version.sql: -------------------------------------------------------------------------------- 1 | USE Contacts; 2 | 3 | DROP PROCEDURE IF EXISTS dbo.InsertContactNotes; 4 | 5 | GO 6 | 7 | CREATE PROCEDURE dbo.InsertContactNotes 8 | ( 9 | @ContactId INT, 10 | @Notes VARCHAR(MAX) 11 | ) 12 | AS 13 | BEGIN; 14 | 15 | DECLARE @NoteTable TABLE (Note VARCHAR(MAX)); 16 | DECLARE @NoteValue VARCHAR(MAX); 17 | 18 | INSERT INTO @NoteTable (Note) 19 | SELECT value 20 | FROM STRING_SPLIT(@Notes, ','); 21 | 22 | DECLARE NoteCursor CURSOR FOR 23 | SELECT Note FROM @NoteTable; 24 | 25 | OPEN NoteCursor 26 | FETCH NEXT FROM NoteCursor INTO @NoteValue; 27 | 28 | WHILE @@FETCH_STATUS = 0 29 | BEGIN; 30 | INSERT INTO dbo.ContactNotes (ContactId, Notes) 31 | VALUES (@ContactId, @NoteValue); 32 | 33 | FETCH NEXT FROM NoteCursor INTO @NoteValue; 34 | 35 | END; 36 | 37 | CLOSE NoteCursor; 38 | DEALLOCATE NoteCursor; 39 | 40 | SELECT * FROM dbo.ContactNotes 41 | WHERE ContactId = @ContactId 42 | ORDER BY NoteId DESC; 43 | 44 | END; 45 | 46 | --test script 47 | DECLARE @TempNotes ContactNote; 48 | 49 | INSERT INTO @TempNotes (Note) 50 | VALUES 51 | ('Hi, Peter called.'), 52 | ('Quick note to let you know Jo wants you to ring her. She rang at 14:30.'), 53 | ('Terri asked about the quote, I have asked her to ring back tomorrow.'); 54 | 55 | EXEC dbo.InsertContactNotes 56 | @ContactId = 23, 57 | @Notes = @TempNotes; 58 | -------------------------------------------------------------------------------- /Stored_Procedures/Insert_Contact_Role_Stored_Procedure.sql: -------------------------------------------------------------------------------- 1 | USE Contacts; 2 | 3 | DROP PROCEDURE IF EXISTS dbo.InsertContactRole; 4 | 5 | GO 6 | 7 | CREATE PROCEDURE dbo.InsertContactRole 8 | ( 9 | @ContactId INT, 10 | @RoleTitle VARCHAR(200) 11 | ) 12 | AS 13 | BEGIN; 14 | 15 | DECLARE @RoleId INT; 16 | 17 | BEGIN TRY; 18 | 19 | BEGIN TRANSACTION; 20 | 21 | IF NOT EXISTS(SELECT 1 FROM dbo.Roles WHERE RoleTitle = @RoleTitle) 22 | BEGIN; 23 | INSERT INTO dbo.Roles (RoleTitle) 24 | VALUES (@RoleTitle); 25 | END; 26 | 27 | SELECT @RoleId = RoleId FROM dbo.Roles WHERE RoleTitle = @RoleTitle; 28 | 29 | IF NOT EXISTS(SELECT 1 FROM dbo.ContactRoles WHERE ContactId = @ContactId AND RoleId = @RoleId) 30 | BEGIN; 31 | INSERT INTO dbo.ContactRoles (ContactId, RoleId) 32 | VALUES (@ContactId, @RoleId); 33 | END; 34 | 35 | COMMIT TRANSACTION; 36 | 37 | SELECT C.ContactId, C.FirstName, C.LastName, R.RoleTitle 38 | FROM dbo.Contacts C 39 | INNER JOIN dbo.ContactRoles CR 40 | ON C.ContactId = CR.ContactId 41 | INNER JOIN dbo.Roles R 42 | ON CR.RoleId = R.RoleId 43 | WHERE C.ContactId = @ContactId; 44 | 45 | END TRY 46 | BEGIN CATCH; 47 | IF (@@TRANCOUNT > 0) 48 | BEGIN; 49 | ROLLBACK TRANSACTION; 50 | END; 51 | PRINT 'Error occurred in ' + ERROR_PROCEDURE() + ' ' + ERROR_MESSAGE(); 52 | RETURN -1; 53 | END CATCH; 54 | 55 | RETURN 0; 56 | 57 | END; 58 | 59 | --test script 60 | DECLARE @RetVal INT; 61 | 62 | EXEC @RetVal = dbo.InsertContactRole 63 | @ContactId = 22, 64 | @RoleTitle = 'Actor'; 65 | 66 | PRINT 'RetVal = ' + CONVERT(VARCHAR(10), @RetVal); -------------------------------------------------------------------------------- /Stored_Procedures/Insert_Contact_Stored Procedure.sql: -------------------------------------------------------------------------------- 1 | USE Contacts; 2 | 3 | GO 4 | 5 | DROP PROCEDURE IF EXISTS dbo.InsertContact; 6 | 7 | GO 8 | 9 | CREATE PROCEDURE dbo.InsertContact 10 | ( 11 | @FirstName VARCHAR(40), 12 | @LastName VARCHAR(40), 13 | @DateOfBirth DATE = NULL, 14 | @AllowContactByPhone BIT, 15 | @ContactId INT OUTPUT 16 | ) 17 | AS 18 | BEGIN; 19 | 20 | SET NOCOUNT ON; 21 | 22 | IF NOT EXISTS (SELECT 1 FROM dbo.Contacts 23 | WHERE FirstName = @FirstName AND @LastName = LastName 24 | AND DateOfBirth = @DateOfBirth) 25 | BEGIN; 26 | INSERT INTO dbo.Contacts (FirstName, LastName, DateOfBirth, AllowContactByPhone) 27 | VALUES (@FirstName, @LastName, @DateOfBirth, @AllowContactByPhone); 28 | 29 | SELECT @ContactId = SCOPE_IDENTITY(); 30 | END; 31 | 32 | EXEC dbo.SelectContact @ContactId = @ContactId; 33 | 34 | SET NOCOUNT OFF; 35 | 36 | END; 37 | 38 | GO -------------------------------------------------------------------------------- /Stored_Procedures/Select_Contacts_Stored _Procedure.sql: -------------------------------------------------------------------------------- 1 | USE Contacts; 2 | 3 | GO 4 | 5 | IF EXISTS(SELECT 1 FROM sys.procedures WHERE [name] = 'SelectContacts') 6 | BEGIN; 7 | DROP PROCEDURE dbo.SelectContacts; 8 | END; 9 | 10 | GO 11 | 12 | CREATE PROCEDURE dbo.SelectContacts 13 | AS 14 | BEGIN; 15 | 16 | SELECT * FROM dbo.Contacts WHERE FirstName = 'Grace'; 17 | 18 | END; 19 | 20 | --Test Script 21 | EXEC dbo.SelectContacts; -------------------------------------------------------------------------------- /Triger_Functions/DDL.sql: -------------------------------------------------------------------------------- 1 | Use WideWorldImporters-Pluralsight; 2 | GO 3 | 4 | /* 5 | Create a DDL trigger in this current database that prevents 6 | altering or dropping a table 7 | */ 8 | CREATE OR ALTER TRIGGER TDB_PreventTableDropOrAlter 9 | ON DATABASE 10 | FOR DROP_TABLE,ALTER_TABLE 11 | AS 12 | BEGIN 13 | PRINT 'DROP and ALTER table events are not allowed. Disable trigger TDB_PreventTableDropOrAlter to complete action.' 14 | ROLLBACK 15 | END 16 | 17 | /* 18 | Attempt to drop our Audit Log table 19 | */ 20 | DROP TABLE Application.AuditLog; 21 | 22 | /* 23 | Attempt to add a column to the Application.Person table 24 | */ 25 | ALTER TABLE Application.People ADD TwitterHandle nvarchar(100); 26 | 27 | /* 28 | Disable the trigger so that we can complete our modification; 29 | */ 30 | DISABLE TRIGGER TDB_PreventTableDropOrAlter ON DATABASE; 31 | 32 | /* 33 | Attempt to add a column to the Application.Person table again 34 | */ 35 | ALTER TABLE Application.People ADD TwitterHandle nvarchar(100); 36 | 37 | /* 38 | Enable the trigger again 39 | */ 40 | ENABLE TRIGGER TDB_PreventTableDropOrAlter ON DATABASE; 41 | GO 42 | 43 | 44 | /************************************* 45 | * 46 | * Log DDL Events to a table 47 | * 48 | *************************************/ 49 | 50 | CREATE TABLE Application.AuditLogDDL 51 | ( 52 | Id INT IDENTITY, 53 | EventTime DATETIME, 54 | EventType NVARCHAR(100), 55 | LoginName NVARCHAR(100), 56 | Command NVARCHAR(MAX) 57 | ) 58 | GO 59 | 60 | /* 61 | This will log ALL DDL events at the database level. 62 | 63 | In reality, this should be refined to only capture events 64 | on specific types OR this audit table should be aggressively 65 | managed to only keep relevant events and table size small. 66 | */ 67 | CREATE TRIGGER AuditLogDDLEvents 68 | ON DATABASE 69 | FOR DDL_DATABASE_LEVEL_EVENTS 70 | AS 71 | BEGIN 72 | SET NOCOUNT ON 73 | DECLARE @EventData XML = EVENTDATA() 74 | INSERT INTO Application.AuditLogDDL(EventTime,EventType,LoginName,Command) 75 | SELECT @EventData.value('(/EVENT_INSTANCE/PostTime)[1]', 'DATETIME'), 76 | @EventData.value('(/EVENT_INSTANCE/EventType)[1]', 'VARCHAR(100)'), 77 | @EventData.value('(/EVENT_INSTANCE/LoginName)[1]', 'VARCHAR(100)'), 78 | @EventData.value('(/EVENT_INSTANCE/TSQLCommand/CommandText)[1]', 'NVARCHAR(MAX)') 79 | END 80 | 81 | 82 | /* 83 | Now, let's perform some DDL Events and see what we get 84 | */ 85 | 86 | /* 87 | Attempt to add a column to the Application.Person table 88 | */ 89 | ALTER TABLE Application.People ADD InstagramHandle nvarchar(100); 90 | 91 | /* 92 | Check the Log 93 | */ 94 | SELECT * FROM Application.AuditLogDDL; 95 | 96 | /* 97 | Disable the trigger so that we can complete our modification; 98 | */ 99 | DISABLE TRIGGER TDB_PreventTableDropOrAlter ON DATABASE; 100 | 101 | /* 102 | Attempt to add a column to the Application.Person table again 103 | */ 104 | ALTER TABLE Application.People ADD InstagramHandle nvarchar(100); 105 | 106 | /* 107 | Check the Log 108 | */ 109 | SELECT * FROM Application.AuditLogDDL; 110 | 111 | 112 | /* 113 | Enable the trigger again 114 | */ 115 | ENABLE TRIGGER TDB_PreventTableDropOrAlter ON DATABASE; 116 | GO -------------------------------------------------------------------------------- /Triger_Functions/DELETE_AFTER Examples.sql: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/Burakkylmz/Programming_SQL_Server_Database/5540ff82dc23522efaaf7cf19a31cfdeb6d9c40c/Triger_Functions/DELETE_AFTER Examples.sql -------------------------------------------------------------------------------- /Triger_Functions/INSERT_AFTER.sql: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/Burakkylmz/Programming_SQL_Server_Database/5540ff82dc23522efaaf7cf19a31cfdeb6d9c40c/Triger_Functions/INSERT_AFTER.sql -------------------------------------------------------------------------------- /Triger_Functions/INSERT_INSTEAD_OF.sql: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/Burakkylmz/Programming_SQL_Server_Database/5540ff82dc23522efaaf7cf19a31cfdeb6d9c40c/Triger_Functions/INSERT_INSTEAD_OF.sql -------------------------------------------------------------------------------- /Triger_Functions/Local_Authentication_Triggers.sql: -------------------------------------------------------------------------------- 1 | USE master; 2 | GO 3 | 4 | /* 5 | Create a new local login to test LOGON Triggers. 6 | 7 | ONLY do something like this in a local, non-shared environment! 8 | */ 9 | CREATE LOGIN login_test WITH PASSWORD = 'abc123!'; 10 | GO 11 | 12 | /* 13 | Grant them access to see DMVs. There are many better ways to 14 | accomplish this in production, but this will work for the demo. 15 | */ 16 | GRANT VIEW SERVER STATE TO login_test; 17 | GO 18 | 19 | /* 20 | Create a LOGON trigger that will limit the number of connections 21 | for this specific user. They cannot open more than 2 connections. 22 | */ 23 | CREATE OR ALTER TRIGGER LimitConnectionsForUser 24 | ON ALL SERVER 25 | FOR LOGON 26 | AS 27 | BEGIN 28 | IF ORIGINAL_LOGIN()= 'login_test' AND 29 | (SELECT COUNT(*) FROM sys.dm_exec_sessions 30 | WHERE is_user_process = 1 AND 31 | original_login_name = 'login_test') > 2 32 | ROLLBACK; 33 | END; 34 | 35 | 36 | 37 | 38 | 39 | /*********************************************** 40 | * 41 | * Create a server-level audit logging database 42 | * 43 | **********************************************/ 44 | 45 | /* 46 | Create an Audit Log Database for server-level events. This 47 | will be owned by my local user for now. 48 | */ 49 | CREATE DATABASE AuditLogDB; 50 | GO 51 | 52 | USE AuditLogDB; 53 | GO 54 | 55 | /* 56 | Create a table within the new database to store login event data 57 | */ 58 | CREATE TABLE LogonEventData 59 | ( 60 | LogonTime datetime, 61 | SPID int, 62 | HostName nvarchar(50), 63 | AppName nvarchar(100), 64 | LoginName nvarchar(50), 65 | ClientHost nvarchar(50) 66 | ); 67 | GO 68 | 69 | /* 70 | Create a second LOGON Trigger to log information. 71 | 72 | This will be executed each time as the owner of the logging 73 | database. Without this, the Trigger would be executed as the 74 | CALLER ('test_login' in this case) and it would return an error 75 | because they do not have permission to write into that 76 | database. 77 | 78 | Much care and thought should be given to how permissions are 79 | used within your environments to protect data and users 80 | appropriately. 81 | */ 82 | CREATE OR ALTER TRIGGER SuccessfulLogonAudit 83 | ON ALL SERVER WITH EXECUTE AS 'RYANB-DEV\Ryan' 84 | FOR LOGON 85 | AS 86 | BEGIN 87 | DECLARE @LogonTriggerData xml, 88 | @EventTime datetime, 89 | @SPID int, 90 | @LoginName nvarchar(50), 91 | @ClientHost nvarchar(50), 92 | @LoginType nvarchar(50), 93 | @HostName nvarchar(50), 94 | @AppName nvarchar(100); 95 | 96 | SET @LogonTriggerData = EventData(); 97 | 98 | SET @EventTime = @LogonTriggerData.value('(/EVENT_INSTANCE/PostTime)[1]', 'datetime'); 99 | SET @SPID = @LogonTriggerData.value('(/EVENT_INSTANCE/SPID)[1]', 'int'); 100 | SET @LoginName = @LogonTriggerData.value('(/EVENT_INSTANCE/LoginName)[1]', 'nvarchar(50)'); 101 | SET @ClientHost = @LogonTriggerData.value('(/EVENT_INSTANCE/ClientHost)[1]', 'nvarchar(50)'); 102 | SET @HostName = HOST_NAME(); 103 | SET @AppName = APP_NAME(); 104 | 105 | INSERT INTO AuditLogDB.dbo.LogonEventData 106 | ( 107 | LogonTime, SPID, HostName, AppName, LoginName, ClientHost 108 | ) 109 | VALUES 110 | ( 111 | @EventTime, @SPID, @HostName, @AppName, @LoginName, @ClientHost 112 | ) 113 | END 114 | GO 115 | 116 | /* 117 | Create a new query window and check the log 118 | */ 119 | SELECT * FROM AuditLogDB.dbo.LogonEventData 120 | ORDER BY LogonTime DESC; 121 | 122 | 123 | /* 124 | We can reset the order of these Triggers. Because everything is run in 125 | the same transaction, more work would be needed to log attempts that 126 | are successful but cross the number of connections limit. 127 | */ 128 | sp_settriggerorder @triggername = 'SuccessfulLogonAudit', @order = 'first', 129 | @stmttype = 'LOGON', @namespace = 'SERVER'; 130 | GO 131 | 132 | sp_settriggerorder @triggername = 'LimitConnectionsForUser', @order = 'last', 133 | @stmttype = 'LOGON', @namespace = 'SERVER'; 134 | GO 135 | 136 | 137 | 138 | 139 | 140 | 141 | 142 | 143 | /* 144 | Cleanup 145 | */ 146 | 147 | DROP TRIGGER LimitConnectionsForUser ON ALL SERVER; 148 | DROP TRIGGER SuccessfulLogonAudit ON ALL SERVER; 149 | 150 | DROP DATABASE AuditLogDB; 151 | 152 | DROP LOGIN login_test; -------------------------------------------------------------------------------- /Triger_Functions/Simple_Function _Samples.sql: -------------------------------------------------------------------------------- 1 | /* 2 | Look at a select statement with three built-in Scalar functions 3 | */ 4 | SELECT MONTH(GETDATE()) AS [MONTH], YEAR(GETDATE()) AS [YEAR]; 5 | GO 6 | 7 | 8 | /* 9 | Create a very simple User-Defined, Multi-Statement Scalar Function 10 | */ 11 | CREATE OR ALTER FUNCTION dbo.SuperAdd_scaler(@a INT, @b INT) 12 | RETURNS INT 13 | WITH SCHEMABINDING 14 | AS 15 | BEGIN 16 | /* 17 | Although this just happens to be one statement, I can have more than 18 | one in a scalar function, so don't let that confuse you. 19 | */ 20 | RETURN @a + @b; 21 | END; 22 | GO 23 | 24 | /* 25 | Do simple addition 26 | */ 27 | select dbo.SuperAdd_scaler(2,2); 28 | GO 29 | 30 | /* 31 | Attempt to pass in bad data 32 | */ 33 | select dbo.SuperAdd_scaler('a',3); 34 | GO 35 | 36 | /* 37 | Create a slightly more complext Multi-Statement Scalar Function that 38 | returns the Fiscal Year Ending of a provided date/time. 39 | 40 | Defaulting to June as the default Fiscal Ending Month 41 | */ 42 | CREATE OR ALTER FUNCTION dbo.FiscalYearEnding(@SaleDate DATETIME, @FiscalEndMonth INT = 6) 43 | RETURNS INT 44 | WITH SCHEMABINDING 45 | AS 46 | BEGIN 47 | DECLARE @saleMonth INT = MONTH(@SaleDate); 48 | DECLARE @saleYear INT = YEAR(@SaleDate); 49 | DECLARE @fiscalYear INT = @saleYear; 50 | 51 | IF(@saleMonth > @FiscalEndMonth AND @FiscalEndMonth != 1) 52 | BEGIN 53 | SET @fiscalYear = @saleYear + 1; 54 | END; 55 | 56 | RETURN @fiscalYear; 57 | END; 58 | GO 59 | 60 | /* 61 | Select a given date and see if we get the correct year 62 | */ 63 | 64 | SELECT '2019-01-01' SampleDate, dbo.FiscalYearEnding('2019-01-01',1) FiscalYear; -- 2019 65 | SELECT '2019-07-01' SampleDate, dbo.FiscalYearEnding('2019-07-01',6) FiscalYear; -- 2020 66 | SELECT '2019-07-01' SampleDate, dbo.FiscalYearEnding('2019-07-01',7) FiscalYear; -- 2019 67 | SELECT '2019-12-01' SampleDate, dbo.FiscalYearEnding('2019-05-01',4) FiscalYear; -- 2020 68 | SELECT '2019-12-01' SampleDate, dbo.FiscalYearEnding('2019-12-01',12) FiscalYear; -- 2019 69 | 70 | /* 71 | Now on some real data 72 | */ 73 | SELECT TOP 100 OrderId, OrderDate, dbo.FiscalYearEnding(OrderDate, DEFAULT) as FiscalSaleYear from Sales.Orders 74 | WHERE OrderDate > '2013-06-28' 75 | GO 76 | 77 | /* 78 | As stated earlier, Scalar Functions are often used in WHERE predicates. Unfortunately 79 | both of these examples are very inefficient because they prevent SARGability, which 80 | we'll discuss in a bit. 81 | 82 | These will both cause the Sales.Orders table to be scanned row-by-row to calculate the 83 | year and fiscal year respectively. 84 | 85 | Finding Orders based on YEAR 86 | */ 87 | SELECT TOP 100 OrderId, OrderDate, dbo.FiscalYearEnding(OrderDate, DEFAULT) as FiscalSaleYear from Sales.Orders 88 | WHERE YEAR(OrderDate) > 2015 89 | GO 90 | 91 | /* 92 | Using our new FiscalYearEnding function 93 | */ 94 | SELECT TOP 100 OrderId, OrderDate, dbo.FiscalYearEnding(OrderDate, DEFAULT) as FiscalSaleYear from Sales.Orders 95 | WHERE dbo.FiscalYearEnding(OrderDate,DEFAULT) > 2015 96 | GO 97 | 98 | 99 | 100 | -------------------------------------------------------------------------------- /Triger_Functions/Trigger_Order.sql: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/Burakkylmz/Programming_SQL_Server_Database/5540ff82dc23522efaaf7cf19a31cfdeb6d9c40c/Triger_Functions/Trigger_Order.sql -------------------------------------------------------------------------------- /Triger_Functions/UPDATE_AFTER.sql: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/Burakkylmz/Programming_SQL_Server_Database/5540ff82dc23522efaaf7cf19a31cfdeb6d9c40c/Triger_Functions/UPDATE_AFTER.sql -------------------------------------------------------------------------------- /src/contactdb.sql: -------------------------------------------------------------------------------- 1 | USE master 2 | 3 | :setvar path "C:\temp\contactsdb\" 4 | 5 | :setvar currentFile "01 Create AddressBook Database.sql" 6 | PRINT 'Executing $(path)$(currentFile)' 7 | :r $(path)$(currentFile) 8 | 9 | :setvar currentFile "10 Create Contacts Table.sql" 10 | PRINT 'Executing $(path)$(currentFile)' 11 | :r $(path)$(currentFile) 12 | 13 | :setvar currentFile "15 Create ContactNotes Table.sql" 14 | PRINT 'Executing $(path)$(currentFile)' 15 | :r $(path)$(currentFile) 16 | 17 | PRINT 'Executing $(path)$(currentFile)' 18 | :setvar currentFile "20 Create Roles Table.sql" 19 | :r $(path)$(currentFile) 20 | 21 | :setvar currentFile "25 Create ContactRoles Table.sql" 22 | PRINT 'Executing $(path)$(currentFile)' 23 | :r $(path)$(currentFile) 24 | 25 | :setvar currentFile "30 Create ContactAddresses Table.sql" 26 | PRINT 'Executing $(path)$(currentFile)' 27 | :r $(path)$(currentFile) 28 | 29 | :setvar currentFile "35 Create PhoneNumberTypes Table.sql" 30 | PRINT 'Executing $(path)$(currentFile)' 31 | :r $(path)$(currentFile) 32 | 33 | :setvar currentFile "40 Create ContactPhoneNumbers Table.sql" 34 | PRINT 'Executing $(path)$(currentFile)' 35 | :r $(path)$(currentFile) 36 | 37 | :setvar currentFile "45 Create ContactVerificationDetails Table.sql" 38 | PRINT 'Executing $(path)$(currentFile)' 39 | :r $(path)$(currentFile) 40 | 41 | :setvar currentFile "50 Insert PhoneNumberTypes.sql" 42 | PRINT 'Executing $(path)$(currentFile)' 43 | :r $(path)$(currentFile) 44 | 45 | :setvar currentFile "55 Contact Table Trigger.sql" 46 | PRINT 'Executing $(path)$(currentFile)' 47 | :r $(path)$(currentFile) 48 | 49 | :setvar currentFile "60 Insert Roles.sql" 50 | PRINT 'Executing $(path)$(currentFile)' 51 | :r $(path)$(currentFile) 52 | 53 | :setvar currentFile "65 Bulk Insert Contacts.sql" 54 | PRINT 'Executing $(path)$(currentFile)' 55 | :r $(path)$(currentFile) 56 | 57 | :setvar currentFile "70 Bulk Insert Contact Addresses.sql" 58 | PRINT 'Executing $(path)$(currentFile)' 59 | :r $(path)$(currentFile) 60 | 61 | :setvar currentFile "75 Bulk Insert ContactNotes.sql" 62 | PRINT 'Executing $(path)$(currentFile)' 63 | :r $(path)$(currentFile) 64 | 65 | :setvar currentFile "80 Bulk Insert ContactPhoneNumbers.sql" 66 | PRINT 'Executing $(path)$(currentFile)' 67 | :r $(path)$(currentFile) 68 | 69 | :setvar currentFile "85 Bulk Insert ContactRoles.sql" 70 | PRINT 'Executing $(path)$(currentFile)' 71 | :r $(path)$(currentFile) 72 | 73 | :setvar currentFile "90 Bulk Insert ContactVerificationDetails.sql" 74 | PRINT 'Executing $(path)$(currentFile)' 75 | :r $(path)$(currentFile) 76 | 77 | PRINT 'All apply scripts successfully executed.' 78 | 79 | USE master --------------------------------------------------------------------------------