├── Aesop ├── Aesop.adp └── Aesop_Create.sql ├── Family ├── Family_Create.sql ├── Family_Queries.sql └── Family_UDF.sql ├── Lessons ├── LESSON_026.SQL ├── LESSON_027.SQL ├── LESSON_028.SQL ├── LESSON_029.SQL ├── LESSON_030.SQL ├── LESSON_031.SQL ├── LESSON_032.SQL ├── LESSON_033.SQL ├── LESSON_034.SQL ├── LESSON_035.SQL ├── LESSON_036.SQL ├── LESSON_037.SQL ├── LESSON_038.SQL ├── LESSON_039.SQL ├── LESSON_040.SQL ├── LESSON_041.SQL ├── LESSON_042.SQL ├── LESSON_043.SQL ├── LESSON_044.SQL ├── LESSON_045.SQL ├── LESSON_046.SQL ├── LESSON_047.SQL ├── LESSON_048.SQL ├── LESSON_049.SQL ├── LESSON_051.SQL ├── LESSON_052.SQL ├── LESSON_053.SQL ├── LESSON_054.SQL ├── LESSON_055.SQL ├── LESSON_056.SQL └── LESSON_057.SQL ├── Northwind.bak └── OBXKites ├── OBXKites_Create.sql └── OBXKites_Populate.sql /Aesop/Aesop.adp: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/alMohamady/SampleDatabases/34b053ebf7b165cc5523e9ec890af036bb1ad998/Aesop/Aesop.adp -------------------------------------------------------------------------------- /Aesop/Aesop_Create.sql: -------------------------------------------------------------------------------- 1 | ----------------------------------------------------------- 2 | -- Aesop's Fables Sample Database 3 | -- For Searching Full-Text Indexes 4 | 5 | ----------------------------------------------------------- 6 | ----------------------------------------------------------- 7 | USE Master 8 | IF EXISTS (SELECT * FROM SysDatabases WHERE NAME='Aesop') 9 | DROP DATABASE Aesop 10 | go 11 | CREATE DATABASE Aesop 12 | go 13 | USE Aesop 14 | 15 | CREATE TABLE Fable ( 16 | FableID INT NOT NULL CONSTRAINT FablePK PRIMARY KEY NONCLUSTERED, 17 | Title VARCHAR(50) NOT NULL, 18 | Moral VARCHAR(100) NOT NULL, 19 | FableText VARCHAR(1536) NOT NULL 20 | ) 21 | go 22 | 23 | SET NOCOUNT ON 24 | 25 | INSERT Fable(FableID, Title, Moral, FableText) 26 | VALUES (1, 'The Ants and the Grasshopper','It is thrifty to prepare today for the wants of tomorrow.', 'The ants were spending a fine winter''s day drying grain collected in the summertime. A Grasshopper, perishing with famine, passed by and earnestly begged for a little food. The Ants inquired of him, "Why did you not treasure up food during the summer?" He replied, "I had not leisure enough. I passed the days in singing." They then said in derision: "If you were foolish enough to sing all the summer, you must dance supperless to bed in the winter.') 27 | INSERT Fable(FableID, Title, Moral, FableText) 28 | VALUES (2, 'The Bald Knight', 'Thy pride is but the prologue of thy shame.', 'A bald knight, who wore a wig, went out to hunt. A sudden puff of wind blew off his hat and wig, at which a loud laugh rang forth from his companions. He pulled up his horse, and with great glee joined in the joke by saying, "What a marvel it is that hairs which are not mine should fly from me, when they have forsaken even the man on whose head they grew."') 29 | INSERT Fable(FableID, Title, Moral, FableText) 30 | VALUES (3, 'Androcles', 'Gratitude is the sign of noble souls.', 'A slave named Androcles once escaped from his master and fled to the forest. As he was wandering about there he came upon a Lion lying down moaning and groaning. At first he turned to flee, but finding that the Lion did not pursue him, he turned back and went up to him. As he came near, the Lion put out his paw, which was all swollen and bleeding, and Androcles found that a huge thorn had got into it, and was causing all the pain. He pulled out the thorn and bound up the paw of the Lion, who was soon able to rise and lick the hand of Androcles like a dog. Then the Lion took Androcles to his cave, and every day used to bring him meat from which to live. But shortly afterwards both Androcles and the Lion were captured, and the slave was sentenced to be thrown to the Lion, after the latter had been kept without food for several days. The Emperor and all his Court came to see the spectacle, and Androcles was led out into the middle of the arena. Soon the Lion was let loose from his den, and rushed bounding and roaring towards his victim. But as soon as he came near to Androcles he recognised his friend, and fawned upon him, and licked his hands like a friendly dog. The Emperor, surprised at this, summoned Androcles to him, who told him the whole story. Whereupon the slave was pardoned and freed, and the Lion let loose to his native forest.') 31 | INSERT Fable(FableID, Title, Moral, FableText) 32 | VALUES (4, 'The Ass in the Lion''s Skin', 'Fine clothes may disguise, but silly words will disclose a fool.', 'An Ass once found a Lion''s skin which the hunters had left out in the sun to dry. He put it on and went towards his native village. All fled at his approach, both men and animals, and he was a proud Ass that day. In his delight he lifted up his voice and brayed, but then every one knew him, and his owner came up and gave him a sound cudgeling for the fright he had caused. And shortly afterwards a Fox came up to him and said: "Ah, I knew you by your voice."') 33 | INSERT Fable(FableID, Title, Moral, FableText) 34 | VALUES (5, 'The Bundle of Sticks', 'Union gives strength.', 'An old man on the point of death summoned his sons around him to give them some parting advice. He ordered his servants to bring in a faggot of sticks, and said to his eldest son, "Break it." The son strained and strained, but with all his efforts was unable to break the Bundle. The other sons also tried, but none of them was successful. "Untie the faggots," said the father, "and each of you take a stick." When they had done so, he called out to them, "Now, break," and each stick was easily broken. "You see my meaning," said their father.') 35 | 36 | INSERT Fable(FableID, Title, Moral, FableText) 37 | VALUES (6, 'The Eagle and the Arrow', 'We often give our enemies the means for our own destruction.', 'An Eagle was soaring through the air when suddenly it heard the whizz of an Arrow, and felt itself wounded to death. Slowly it fluttered down to the earth, with its life-blood pouring out of it. Looking down upon the Arrow with which it had been pierced, it found that the shaft of the Arrow had been feathered with one of its own plumes. "Alas!" it cried, as it died.') 38 | INSERT Fable(FableID, Title, Moral, FableText) 39 | VALUES (7, 'The Dove and the Ant', 'Little friends may prove great friends.', 'An Ant, going to a river to drink, fell in, and was carried along in the stream. A Dove pitied her condition, and threw into the river a small bough, by means of which the Ant gained the shore. The Ant afterward, seeing a man with a fowling-piece aiming at the Dove, stung him in the foot sharply, and made him miss his aim, and so saved the Dove''s life.') 40 | INSERT Fable(FableID, Title, Moral, FableText) 41 | VALUES (8, 'The Woodman and the Serpent', 'No gratitude from the wicked.', 'One wintry day a Woodman was tramping home from his work when he saw something black lying on the snow. When he came closer he saw it was a Serpent to all appearance dead. But he took it up and put it in his bosom to warm while he hurried home. As soon as he got indoors he put the Serpent down on the hearth before the fire. The children watched it and saw it slowly come to life again. Then one of them stooped down to stroke it, but the Serpent raised its head and put out its fangs and was about to sting the child to death. So the Woodman seized his axe, and with one stroke cut the Serpent in two. "Ah," said he.') 42 | INSERT Fable(FableID, Title, Moral, FableText) 43 | VALUES (9, 'The Wolf and the Kid', 'It is easy to be brave from a safe distance.', 'A Kid was perched up on the top of a house, and looking down saw a Wolf passing under him. Immediately he began to revile and attack his enemy. "Murderer and thief," he cried, "what do you here near honest folks'' houses? How dare you make an appearance where your vile deeds are known?" "Curse away, my young friend," said the Wolf.') 44 | INSERT Fable(FableID, Title, Moral, FableText) 45 | VALUES (10, 'The Old Woman and the Wine-Jar', 'The memory of a good deed lives.', 'An old woman found an empty jar which had lately been full of prime old wine and which still retained the fragrant smell of its former contents. She greedily placed it several times to her nose, and drawing it backwards and forwards said, "O most delicious! How nice must the Wine itself have been, when it leaves behind in the very vessel which contained it so sweet a perfume!"') 46 | 47 | INSERT Fable(FableID, Title, Moral, FableText) 48 | VALUES (11, 'The Hare and the Tortoise', 'Plodding wins the race."', 'The Hare was once boasting of his speed before the other animals. "I have never yet been beaten," said he, "when I put forth my full speed. I challenge any one here to race with me." The Tortoise said quietly, "I accept your challenge." "That is a good joke," said the Hare; "I could dance round you all the way." "Keep your boasting till you''ve beaten," answered the Tortoise. "Shall we race?" So a course was fixed and a start was made. The Hare darted almost out of sight at once, but soon stopped and, to show his contempt for the Tortoise, lay down to have a nap. The Tortoise plodded on and plodded on, and when the Hare awoke from his nap, he saw the Tortoise just near the winning-post and could not run up in time to save the race. Then said the Tortoise: Plodding wins the race.') 49 | INSERT Fable(FableID, Title, Moral, FableText) 50 | VALUES (12, 'The Goose With the Golden Eggs', 'Greed often over reaches itself.', 'One day a countryman going to the nest of his Goose found there an egg all yellow and glittering. When he took it up it was as heavy as lead and he was going to throw it away, because he thought a trick had been played upon him. But he took it home on second thoughts, and soon found to his delight that it was an egg of pure gold. Every morning the same thing occurred, and he soon became rich by selling his eggs. As he grew rich he grew greedy; and thinking to get at once all the gold the Goose could give, he killed it and opened it only to find nothing. ') 51 | INSERT Fable(FableID, Title, Moral, FableText) 52 | VALUES (13, 'The Eagle and the Fox', 'Do unto others as you would have them do unto you.', 'An eagle and a Fox formed an intimate friendship and decided to live near each other. The Eagle built her nest in the branches of a tall tree, while the Fox crept into the underwood and there produced her young. Not long after they had agreed upon this plan, the Eagle, being in want of provision for her young ones, swooped down while the Fox was out, seized upon one of the little cubs, and feasted herself and her brood. The Fox on her return, discovered what had happened, but was less grieved for the death of her young than for her inability to avenge them. A just retribution, however, quickly fell upon the Eagle. While hovering near an altar, on which some villagers were sacrificing a goat, she suddenly seized a piece of the flesh, and carried it, along with a burning cinder, to her nest. A strong breeze soon fanned the spark into a flame, and the eaglets, as yet unfledged and helpless, were roasted in their nest and dropped down dead at the bottom of the tree. There, in the sight of the Eagle, the Fox gobbled them up.') 53 | INSERT Fable(FableID, Title, Moral, FableText) 54 | VALUES (14, 'The Dogs and the Fox', 'It is easy to kick a man that is down.', 'Some dogs, finding the skin of a lion, began to tear it in pieces with their teeth. A Fox, seeing them, said, "If this lion were alive, you would soon find out that his claws were stronger than your teeth." ') 55 | INSERT Fable(FableID, Title, Moral, FableText) 56 | VALUES (15, 'The Ant and the Chrysalis', 'Appearances are deceptive.', 'An Ant nimbly running about in the sunshine in search of food came across a Chrysalis that was very near its time of change. The Chrysalis moved its tail, and thus attracted the attention of the Ant, who then saw for the first time that it was alive. "Poor, pitiable animal!" cried the Ant disdainfully. "What a sad fate is yours! While I can run hither and thither, at my pleasure, and, if I wish, ascend the tallest tree, you lie imprisoned here in your shell, with power only to move a joint or two of your scaly tail." The Chrysalis heard all this, but did not try to make any reply. A few days after, when the Ant passed that way again, nothing but the shell remained. Wondering what had become of its contents, he felt himself suddenly shaded and fanned by the gorgeous wings of a beautiful Butterfly. "Behold in me," said the Butterfly, "your much-pitied friend! Boast now of your powers to run and climb as long as you can get me to listen." So saying, the Butterfly rose in the air, and, borne along and aloft on the summer breeze, was soon lost to the sight of the Ant forever.') 57 | 58 | INSERT Fable(FableID, Title, Moral, FableText) 59 | VALUES (16, 'The Shipwrecked Impostor', 'A liar deceives no one but himself.', 'The shipwrecked Chimpanzee had been clinging for a long time to a slender spar, when a Dolphin came up and offered to carry him ashore. This kind proposition was immediately accepted, and, as they moved along, the Chimp commenced to tell the Fish many marvelous tales, every one of them a bundle of falsehoods. "Well, well, you are indeed an educated chap," said the Dolphin in admiration. "My schooling has been sadly neglected, as I went to sea when but a week old." Just then they entered a large bay, and the Dolphin, referring to it, said, "I suppose you know Herring Roads?" The chimp, taking this for the name of a fellow, and not wishing to appear ignorant, replied: "Do I know Rhodes? Well, I should almost think so! He''s an old college chum of mine, and related to our family by-" This was too much for the Dolphin, who immediately made a great leap, and then diving quickly, left the impostor in the air for an instant before he splashed back and disappeared.') 60 | INSERT Fable(FableID, Title, Moral, FableText) 61 | VALUES (17, 'The Seagull and the Kite', 'Every man should be content to mind his own business.', 'A seagull having bolted down too large a fish, burst its deep gullet-bag and lay down on the shore to die. A Kite saw him and exclaimed, "You richly deserve your fate; for a bird of the air has no business to seek its food from the sea."') 62 | INSERT Fable(FableID, Title, Moral, FableText) 63 | VALUES (18, 'Hercules and the Waggoner', 'The gods help them that help themselves.', 'A Waggoner was once driving a heavy load along a very muddy way. At last he came to a part of the road where the wheels sank half-way into the mire, and the more the horses pulled, the deeper sank the wheels. So the Waggoner threw down his whip, and knelt down and prayed to Hercules the Strong. "O Hercules, help me in this my hour of distress," quoth he. But Hercules appeared to him, and said: "Tut, man, don''t sprawl there. Get up and put your shoulder to the wheel."') 64 | INSERT Fable(FableID, Title, Moral, FableText) 65 | VALUES (19, 'The Boy and the Filberts', 'Do not attempt too much at once.', 'A boy put his hand into a pitcher full of filberts. He grasped as many as he could possibly hold, but when he tried to pull out his hand, he was prevented from doing so by the neck of the pitcher. Unwilling to lose his filberts, and yet unable to withdraw his hand, he burst into tears and bitterly lamented his disappointment. A bystander said to him, "Be satisfied with half the quantity, and you will readily draw out your hand."') 66 | INSERT Fable(FableID, Title, Moral, FableText) 67 | VALUES (20, 'The Hunter and the Woodman', 'The hero is brave in deeds as well as words.', 'A hunter, not very bold, was searching for the tracks of a Lion. He asked a man felling oaks in the forest if he had seen any marks of his footsteps or knew where his lair was. "I will," said the man, "at once show you the Lion himself." The Hunter, turning very pale and chattering with his teeth from fear, replied, "No, thank you. I did not ask that; it is his track only I am in search of, not the Lion himself."') 68 | 69 | INSERT Fable(FableID, Title, Moral, FableText) 70 | VALUES (21, 'The Crow and the Pitcher', 'Necessity is the mother of invention.', 'A crow perishing with thirst saw a pitcher, and hoping to find water, flew to it with delight. When he reached it, he discovered to his grief that it contained so little water that he could not possibly get at it. He tried everything he could think of to reach the water, but all his efforts were in vain. At last he collected as many stones as he could carry and dropped them one by one with his beak into the pitcher, until he brought the water within his reach and thus saved his life.') 71 | INSERT Fable(FableID, Title, Moral, FableText) 72 | VALUES (22, 'The Father and His Two Daughters', 'You can''t please everybody.', 'A man had two daughters, the one married to a gardener, and the other to a tile-maker. After a time he went to the daughter who had married the gardener, and inquired how she was and how all things went with her. She said, "All things are prospering with me, and I have only one wish, that there may be a heavy fall of rain, in order that the plants may be well watered." Not long after, he went to the daughter who had married the tilemaker, and likewise inquired of her how she fared; she replied, "I want for nothing, and have only one wish, that the dry weather may continue, and the sun shine hot and bright, so that the bricks might be dried." He said to her, "If your sister wishes for rain, and you for dry weather, with which of the two am I to join my wishes?') 73 | INSERT Fable(FableID, Title, Moral, FableText) 74 | VALUES (23, 'The Horse and Groom', 'A man may smile yet be a villain.', 'A groom used to spend whole days in currycombing and rubbing down his Horse, but at the same time stole his oats and sold them for his own profit. "Alas!" said the Horse, "if you really wish me to be in good condition, you should groom me less, and feed me more."') 75 | INSERT Fable(FableID, Title, Moral, FableText) 76 | VALUES (24, 'The Serpent and the Eagle', 'One good turn deserves another.', 'An Eagle swooped down upon a Serpent and seized it in his talons with the intention of carrying it off and devouring it. But the Serpent was too quick for him and had its coils round him in a moment; and then there ensued a life-and-death struggle between the two. A countryman, who was a witness of the encounter, came to the assistance of the eagle, and succeeded in freeing him from the Serpent and enabling him to escape. In revenge, the Serpent spat some of his poison into the man''s drinking-horn. Heated with his exertions, the man was about to slake his thirst with a draught from the horn, when the Eagle knocked it out of his hand, and spilled its contents upon the ground.') 77 | INSERT Fable(FableID, Title, Moral, FableText) 78 | VALUES (25, 'The Shepherd''s Boy and the Wolf', 'There is no believing a liar, even when he speaks the truth.', 'A shepherd-boy, who watched a flock of sheep near a village, brought out the villagers three or four times by crying out, "Wolf! Wolf!" and when his neighbors came to help him, laughed at them for their pains. The Wolf, however, did truly come at last. The Shepherd-boy, now really alarmed, shouted in an agony of terror: "Pray, do come and help me; the Wolf is killing the sheep"; but no one paid any heed to his cries, nor rendered any assistance. The Wolf, having no cause of fear, at his leisure lacerated or destroyed the whole flock.') 79 | 80 | USE Aesop 81 | SELECT Title, Len(FableText) AS Length 82 | FROM Fable 83 | ORDER BY 84 | CASE 85 | WHEN SubString(Title, 1,3) = 'The' 86 | THEN SubString(Title, 5, Len(Title)-4) 87 | ELSE Title 88 | END 89 | 90 | USE MASTER 91 | 92 | 93 | 94 | 95 | 96 | -------------------------------------------------------------------------------- /Family/Family_Create.sql: -------------------------------------------------------------------------------- 1 | 2 | ----------------------------------------------------------- 3 | -- Family sample database - CREATE 4 | 5 | -- this script will drop an existing Family database 6 | -- and create a fresh new installation 7 | 8 | ----------------------------------------------------------- 9 | ----------------------------------------------------------- 10 | -- Drop and Create Database 11 | 12 | 13 | USE master 14 | GO 15 | IF EXISTS (SELECT * FROM SysDatabases WHERE NAME='Family') 16 | DROP DATABASE Family 17 | go 18 | 19 | -- This creates the database data file and log file on the default directories 20 | CREATE DATABASE Family 21 | go 22 | 23 | use Family 24 | go 25 | 26 | 27 | ----------------------------------------------------------- 28 | ----------------------------------------------------------- 29 | -- Create Tables, in order from primary to secondary 30 | 31 | CREATE TABLE dbo.Person ( 32 | PersonID INT NOT NULL PRIMARY KEY NONCLUSTERED, 33 | LastName VARCHAR(15) NOT NULL, 34 | FirstName VARCHAR(15) NOT NULL, 35 | SrJr VARCHAR(3) NULL, 36 | MaidenName VARCHAR(15) NULL, 37 | Gender CHAR(1) NOT NULL, 38 | FatherID INT NULL, 39 | MotherID INT NULL, 40 | DateOfBirth DATETIME NULL, 41 | DateOfDeath DATETIME NULL 42 | ); 43 | 44 | go 45 | CREATE CLUSTERED INDEX IxPersonName 46 | ON dbo.Person (LastName, FirstName); 47 | ALTER TABLE dbo.Person ADD CONSTRAINT 48 | FK_Person_Father FOREIGN KEY (FatherID) REFERENCES dbo.Person (PersonID); 49 | ALTER TABLE dbo.Person ADD CONSTRAINT 50 | FK_Person_Mother FOREIGN KEY (MotherID) REFERENCES dbo.Person (PersonID); 51 | go 52 | 53 | CREATE TABLE dbo.Marriage ( 54 | MarriageID INT NOT NULL PRIMARY KEY NONCLUSTERED, 55 | HusbandID INT NOT NULL FOREIGN KEY REFERENCES dbo.Person, 56 | WifeID INT NOT NULL FOREIGN KEY REFERENCES dbo.Person, 57 | DateOfWedding DATETIME NULL, 58 | DateOfDivorce DATETIME NULL 59 | ) 60 | go 61 | 62 | ---------------------------------------------------------------------------- 63 | -- Custom Constraints 64 | 65 | CREATE TRIGGER Person_Parents 66 | ON Person 67 | AFTER INSERT, UPDATE 68 | AS 69 | -- check that if the parent is listed that the gender is correct 70 | 71 | IF UPDATE(FatherID) 72 | BEGIN 73 | -- Incorrect Father Gender 74 | IF EXISTS(SELECT * FROM Person JOIN Inserted ON Inserted.FatherID = Person.PersonID WHERE Person.Gender = 'F') 75 | BEGIN 76 | ROLLBACK 77 | RAISERROR('Incorrect Gender for Father',14,1) 78 | RETURN 79 | END 80 | END 81 | 82 | -- Invalid Father Age 83 | 84 | 85 | -- Father Deceased 86 | 87 | 88 | IF UPDATE(MotherID) 89 | BEGIN 90 | -- Incorrect Mother Gender 91 | IF EXISTS(SELECT * FROM Person JOIN Inserted ON Inserted.MotherID = Person.PersonID WHERE Person.Gender = 'M') 92 | BEGIN 93 | ROLLBACK 94 | RAISERROR('Incorrect Gender for Mother',14,1) 95 | RETURN 96 | END 97 | END 98 | 99 | -- Invalid Mother age 100 | 101 | 102 | 103 | -- Mother Deceased 104 | 105 | 106 | RETURN 107 | 108 | 109 | go 110 | ---------------------------------------------------------------------------- 111 | -- Sample Data 112 | 113 | INSERT dbo.Person (PersonID, LastName, FirstName, MaidenName, Gender, FatherID, MotherID, DateOfBirth, DateOfDeath) 114 | VALUES(1, 'Halloway', 'Kelly', 'Russell', 'F', NULL, NULL, '2/7/1904','5/13/1987') 115 | INSERT dbo.Person (PersonID, LastName, FirstName, SrJr, Gender, FatherID, MotherID, DateOfBirth, DateOfDeath) 116 | VALUES(2, 'Halloway', 'James', '1', 'M', NULL, NULL, '4/12/1899','5/1/2001') 117 | INSERT dbo.Person (PersonID, LastName, FirstName, MaidenName, Gender, FatherID, MotherID, DateOfBirth, DateOfDeath) 118 | VALUES(3,'Miller', 'Karen', 'Conley', 'F', NULL, NULL, '9/11/1909','8/1/1974') 119 | INSERT dbo.Person (PersonID, LastName, FirstName, SrJr, Gender, FatherID, MotherID, DateOfBirth, DateOfDeath) 120 | VALUES(4, 'Miller', 'Bryan', NULL, 'M', NULL, NULL, '4/12/1902','4/16/1948') 121 | go 122 | INSERT dbo.Person (PersonID, LastName, FirstName, SrJr, Gender, FatherID, MotherID, DateOfBirth, DateOfDeath) 123 | VALUES(5, 'Halloway', 'James', '2', 'M', 2, 1, '5/19/1922','2/2/1992') 124 | INSERT dbo.Person (PersonID, LastName, FirstName, MaidenName, Gender, FatherID, MotherID, DateOfBirth, DateOfDeath) 125 | VALUES(6, 'Halloway', 'Audry', 'Ross', 'F', 4, 3, '8/5/1928','3/12/2002') 126 | go 127 | INSERT dbo.Person (PersonID, LastName, FirstName, SrJr, Gender, FatherID, MotherID, DateOfBirth, DateOfDeath) 128 | VALUES(7, 'Halloway', 'Corwin', NULL, 'M', 5, 6, '3/13/1961',NULL) 129 | INSERT dbo.Person (PersonID, LastName, FirstName, MaidenName, Gender, FatherID, MotherID, DateOfBirth, DateOfDeath) 130 | VALUES(8, 'Campbell', 'Melanie', 'Halloway', 'F', 5, 6, '8/19/1951','6/28/2009') 131 | INSERT dbo.Person (PersonID, LastName, FirstName, SrJr, Gender, FatherID, MotherID, DateOfBirth, DateOfDeath) 132 | VALUES(9, 'Halloway', 'Dara', NULL, 'F', 5, 6, '12/12/1958','4/14/2010') 133 | INSERT dbo.Person (PersonID, LastName, FirstName, SrJr, Gender, FatherID, MotherID, DateOfBirth, DateOfDeath) 134 | VALUES(10, 'Halloway', 'James', 3, 'M', 5, 6, '8/30/1953','11/30/2007') 135 | go 136 | INSERT dbo.Person (PersonID, LastName, FirstName, SrJr, Gender, FatherID, MotherID, DateOfBirth, DateOfDeath) 137 | VALUES(11, 'Kidd', 'Kimberly', NULL, 'F', NULL, NULL, '7/24/1963',NULL) 138 | INSERT dbo.Person (PersonID, LastName, FirstName, MaidenName, Gender, FatherID, MotherID, DateOfBirth, DateOfDeath) 139 | VALUES(12, 'Halloway', 'Alysia', 'Simmons', 'F', NULL, NULL, '3/5/1953',NULL) 140 | INSERT dbo.Person (PersonID, LastName, FirstName, SrJr, Gender, FatherID, MotherID, DateOfBirth, DateOfDeath) 141 | VALUES(13, 'Ramsey', 'Walter ', NULL, 'M', NULL, NULL, '9/30/1945',NULL) 142 | go 143 | INSERT dbo.Person (PersonID, LastName, FirstName, SrJr, Gender, FatherID, MotherID, DateOfBirth, DateOfDeath) 144 | VALUES(14, 'Halloway', 'Logan', NULL, 'M', 7, 11,'2/6/1994',NULL) 145 | INSERT dbo.Person (PersonID, LastName, FirstName, SrJr, Gender, FatherID, MotherID, DateOfBirth, DateOfDeath) 146 | VALUES(15, 'Ramsey', 'Shannon', NULL, 'F', 13, 8,'4/1/1970',NULL) 147 | INSERT dbo.Person (PersonID, LastName, FirstName, SrJr, Gender, FatherID, MotherID, DateOfBirth, DateOfDeath) 148 | VALUES(16, 'Ramsey', 'Jennifer', NULL, 'F', 13, 8,'6/1/1972','6/1/1972') 149 | INSERT dbo.Person (PersonID, LastName, FirstName, SrJr, Gender, FatherID, MotherID, DateOfBirth, DateOfDeath) 150 | VALUES(17, 'Halloway', 'Allie', NULL, 'F', 10, 12,'8/14/1979',NULL) 151 | INSERT dbo.Person (PersonID, LastName, FirstName, SrJr, Gender, FatherID, MotherID, DateOfBirth, DateOfDeath) 152 | VALUES(18, 'Halloway', 'Abbie', NULL, 'F', 10, 12,'8/14/1979',NULL) 153 | INSERT dbo.Person (PersonID, LastName, FirstName, SrJr, Gender, FatherID, MotherID, DateOfBirth, DateOfDeath) 154 | VALUES(19, 'Halloway', 'James', 4, 'M',10, 12,'5/24/1975',NULL) 155 | INSERT dbo.Person (PersonID, LastName, FirstName, MaidenName, Gender, FatherID, MotherID, DateOfBirth, DateOfDeath) 156 | VALUES(20, 'Halloway', 'Grace', 'Stranes', 'F', NULL, NULL,'11/1/1977',NULL) 157 | go 158 | INSERT dbo.Person (PersonID, LastName, FirstName, SrJr, Gender, FatherID, MotherID, DateOfBirth, DateOfDeath) 159 | VALUES(21, 'Halloway', 'James', 5, 'M', 19, 20,'9/4/2007',NULL) 160 | INSERT dbo.Person (PersonID, LastName, FirstName, SrJr, Gender, FatherID, MotherID, DateOfBirth, DateOfDeath) 161 | VALUES(22, 'Halloway', 'Chris', NULL, 'M', 19, 20, '7/4/2003',NULL) 162 | go 163 | INSERT dbo.Person (PersonID, LastName, FirstName, SrJr, Gender, FatherID, MotherID, DateOfBirth, DateOfDeath) 164 | VALUES(23, 'Halloway', 'Joshua', NULL, 'M', NULL, 9,'6/25/1975',NULL) 165 | INSERT dbo.Person (PersonID, LastName, FirstName, SrJr, Gender, FatherID, MotherID, DateOfBirth, DateOfDeath) 166 | VALUES(24, 'Halloway', 'Laura', NULL, 'F', NULL, 9, '5/29/1977',NULL) 167 | INSERT dbo.Person (PersonID, LastName, FirstName, MaidenName, Gender, FatherID, MotherID, DateOfBirth, DateOfDeath) 168 | VALUES(25, 'Halloway', 'Katherine', 'Wood', 'F', NULL, NULL,'3/23/1996',NULL) 169 | INSERT dbo.Person (PersonID, LastName, FirstName, SrJr, Gender, FatherID, MotherID, DateOfBirth, DateOfDeath) 170 | VALUES(26, 'Campbell', 'Richard', NULL, 'M', NULL, NULL,'1/16/1941',NULL) 171 | go 172 | INSERT dbo.Person (PersonID, LastName, FirstName, SrJr, Gender, FatherID, MotherID, DateOfBirth, DateOfDeath) 173 | VALUES(29, 'Campbell', 'Adam', NULL, 'M', 26, 8,'1/30/1981',NULL) 174 | INSERT dbo.Person (PersonID, LastName, FirstName, MaidenName, Gender, FatherID, MotherID, DateOfBirth, DateOfDeath) 175 | VALUES(30, 'Campbell', 'Amy', 'Johnson', 'F', NULL, NULL,'2/27/1959',NULL) 176 | INSERT dbo.Person (PersonID, LastName, FirstName, MaidenName, Gender, FatherID, MotherID, DateOfBirth, DateOfDeath) 177 | VALUES(32, 'Campbell', 'Elizabeth', 'Straka', 'F', NULL, NULL, '6/24/1939','1/1/1972') 178 | go 179 | INSERT dbo.Person (PersonID, LastName, FirstName, SrJr, Gender, FatherID, MotherID, DateOfBirth, DateOfDeath) 180 | VALUES(27, 'Campbell', 'Alexia', NULL, 'F', 26 , 32, '8/12/1970','1/1/1972') 181 | INSERT dbo.Person (PersonID, LastName, FirstName, SrJr, Gender, FatherID, MotherID, DateOfBirth, DateOfDeath) 182 | VALUES(28, 'Campbell', 'Cameron', NULL, 'M', 26, 32,'3/13/1965',NULL) 183 | go 184 | INSERT dbo.Person (PersonID, LastName, FirstName, SrJr, Gender, FatherID, MotherID, DateOfBirth, DateOfDeath) 185 | VALUES(31, 'Campbell', 'William', NULL, 'M', 28, 30, '1/1/1987','6/30/1997') 186 | 187 | go 188 | 189 | INSERT dbo.Marriage(MarriageID, HusbandID, WifeID, DateOfWedding, DateOfDivorce) 190 | VALUES(1, 2, 1, '6/20/1920', NULL) 191 | INSERT dbo.Marriage(MarriageID, HusbandID, WifeID, DateOfWedding, DateOfDivorce) 192 | VALUES(2, 4, 3 , '4/14/1926', NULL) 193 | INSERT dbo.Marriage(MarriageID, HusbandID, WifeID, DateOfWedding, DateOfDivorce) 194 | VALUES(3, 5, 6, '12/1/1948', NULL) 195 | INSERT dbo.Marriage(MarriageID, HusbandID, WifeID, DateOfWedding, DateOfDivorce) 196 | VALUES(4, 10, 12 , '1/1/1975', NULL) 197 | INSERT dbo.Marriage(MarriageID, HusbandID, WifeID, DateOfWedding, DateOfDivorce) 198 | VALUES(5, 13, 8, '5/2/1968', '1/1/1974') 199 | INSERT dbo.Marriage(MarriageID, HusbandID, WifeID, DateOfWedding, DateOfDivorce) 200 | VALUES(6, 14, 25, '4/14/2018', NULL) 201 | INSERT dbo.Marriage(MarriageID, HusbandID, WifeID, DateOfWedding, DateOfDivorce) 202 | VALUES(7, 26, 8, '9/4/1977', NULL) 203 | INSERT dbo.Marriage(MarriageID, HusbandID, WifeID, DateOfWedding, DateOfDivorce) 204 | VALUES(8, 19, 20, '8/25/2000', '1/1/2007') 205 | INSERT dbo.Marriage(MarriageID, HusbandID, WifeID, DateOfWedding, DateOfDivorce) 206 | VALUES(9, 28, 30, '6/2/1984', NULL) 207 | INSERT dbo.Marriage(MarriageID, HusbandID, WifeID, DateOfWedding, DateOfDivorce) 208 | VALUES(10, 26, 32, '4/14/1963', NULL) 209 | 210 | SELECT * FROM Person 211 | 212 | SELECT * FROM Marriage 213 | 214 | -------------------------------------------------------------------------------- /Family/Family_Queries.sql: -------------------------------------------------------------------------------- 1 | ----------------------------------------------------------- 2 | -- 14 Fun Family Queries 3 | ----------------------------------------------------------- 4 | 5 | USE Family 6 | 7 | ----------------------------------------------------------- 8 | -- Raw Data 9 | SELECT * FROM Person ORDER BY PersonID 10 | SELECT * FROM Marriage ORDER BY DateOfWedding 11 | 12 | 13 | ---------------------------------------------------------- 14 | -- 1) Who died, when, who old were they? 15 | SELECT FirstName, LastName, CONVERT(VARCHAR(12),DateOfDeath,101) AS Death, 16 | DATEDIFF(yy,DateOfBirth, DateOfDeath) AS Age 17 | FROM Person 18 | WHERE DateOfDeath IS NOT NULL 19 | ORDER BY DateOfDeath 20 | 21 | ---------------------------------------------------------- 22 | -- 2) Who was alive on 1/1/2001 and how old were they? 23 | SELECT FirstName, LastName, DATEDIFF(yy,DateOfBirth, '1/1/2001') AS Age 24 | FROM Person 25 | WHERE DateOfBirth <= '1/1/2001' 26 | AND (DateOfDeath IS NULL 27 | OR DateOfDeath >= '1/1/2001' ) 28 | ORDER BY Age DESC 29 | 30 | ----------------------------------------------------------- 31 | -- 3) List all James Halloways 32 | SELECT FirstName, LastName, SrJr, 33 | CONVERT(VARCHAR(12),DateOfBirth,101) AS Birth, 34 | CONVERT(VARCHAR(12),DateOfDeath,101) AS Death 35 | FROM Person 36 | WHERE FirstName = 'James' 37 | AND LastName = 'Halloway' 38 | AND SrJr IS NOT NULL 39 | ORDER BY DateOfBirth 40 | 41 | 42 | ----------------------------------------------------------- 43 | -- 4) List all Weddings and age of bride and groom 44 | SELECT CONVERT( VARCHAR(12), DateOfWedding,101) AS WeddingDate, 45 | H.FirstName + ' ' + H.LastName + ISNULL(' ' + H.SrJr,'') AS Groom, 46 | DATEDIFF(yy,H.DateOfBirth, Marriage.DateOfWedding) AS GroomAge, 47 | W.FirstName + ' ' + W.MaidenName AS Bride, 48 | DATEDIFF(yy,W.DateOfBirth, Marriage.DateOfWedding) AS BrideAge 49 | FROM Marriage 50 | JOIN Person H 51 | ON Marriage.HusbandID = H.personID 52 | JOIN Person W 53 | ON Marriage.WifeID = W.personID 54 | ORDER BY DateOfWedding 55 | 56 | ----------------------------------------------------------- 57 | -- 5) Who got divorced? and How long were they married? 58 | SELECT Person.FirstName + ' ' + Person.LastName AS XHubby, 59 | Wife.FirstName + ' ' + Wife.LastName AS XWife, DateOfDivorce, 60 | DATEDIFF(yy, DateOfWedding, DateOfDivorce) AS YrsMarried 61 | FROM Person 62 | JOIN Marriage 63 | ON Person.PersonID = Marriage.HusbandID 64 | JOIN Person Wife 65 | ON Marriage.WifeID = WIfe.PersonID 66 | WHERE DateOfDivorce IS NOT NULL 67 | 68 | 69 | ----------------------------------------------------------- 70 | -- 6) List all births including their mother and father (if known) check 71 | SELECT Person.PersonID, CONVERT(NVARCHAR(15), Person.DateofBirth,1) AS Date, 72 | Person.FirstName, 73 | Person.Gender, ISNULL(F.FirstName + ' ' + F.LastName, ' * unknown *') as Father, 74 | M.FirstName + ' ' + M.LastName as Mother 75 | FROM Person 76 | Left Outer JOIN Person F 77 | ON Person.FatherID = F.PersonID 78 | INNER JOIN Person M 79 | ON Person.MotherID = M.PersonID 80 | ORDER BY Person.DateOfBirth 81 | 82 | ----------------------------------------------------------- 83 | -- 7) How many children has each mother born? 84 | SELECT PersonID, FirstName, LastName, Children 85 | FROM Person 86 | JOIN (SELECT MotherID, COUNT(*) AS Children 87 | FROM Person 88 | WHERE MotherID IS NOT NULL 89 | GROUP BY MotherID) ChildCount 90 | ON Person.PersonID = ChildCount.MotherID 91 | ORDER BY Children DESC 92 | 93 | 94 | ----------------------------------------------------------- 95 | -- 8) Who remarried? 96 | SELECT Person.FirstName + ' ' + Person.LastName 97 | FROM Person 98 | WHERE 99 | PersonID IN 100 | (SELECT HusbandID FROM Marriage GROUP BY HusbandID Having Count(*) > 1) 101 | OR 102 | PersonID IN 103 | (SELECT WifeID FROM Marriage GROUP BY WifeID Having Count(*) > 1) 104 | 105 | -- Carl's solution 106 | SELECT MarriageCnt, Person.* 107 | FROM Person 108 | join (select HusbandID as PersonId , count(*) as MarriageCnt 109 | from Marriage 110 | group by HusbandID 111 | having count(*) > 1 112 | union all 113 | select WifeID as PersonId , count(*) as MarriageCnt 114 | from Marriage 115 | group by WifeID 116 | having count(*) > 1 117 | ) as Marriages 118 | on Person.PersonId = Marriages.PersonId 119 | 120 | 121 | 122 | ----------------------------------------------------------- 123 | -- 9) How old were the mothers when their children were born? 124 | SELECT Person.FirstName + ' ' + Person.LastName AS Mother, 125 | DATEDIFF(yy, Person.DateOfBirth, Child.DateOfBirth) AS Age, 126 | Child.FirstName 127 | FROM Person 128 | JOIN Person Child 129 | ON Person.PersonID = Child.MotherID 130 | ORDER By Age DESC 131 | 132 | 133 | ----------------------------------------------------------- 134 | -- 10) Who had a child less than 9 months after the wedding, regardless of who is the father? 135 | SELECT Person.FirstName + ' ' + Person.LastName AS Mother, 136 | Convert(Char(12), Marriage.DateOfWedding, 107) as Wedding, 137 | Child.FirstName + ' ' + Child.LastName as Child, 138 | Convert(Char(12), Child.DateOfBirth, 107) as Birth 139 | FROM Person 140 | JOIN Marriage 141 | ON Person.PersonID = Marriage.WifeID 142 | JOIN Person Child 143 | ON Person.PersonID = Child.MotherID 144 | WHERE Child.DateOfBirth 145 | BETWEEN Marriage.DateOfWedding AND DATEADD(mm, 9, Marriage.DateOfWedding) 146 | 147 | 148 | ----------------------------------------------------------- 149 | -- 11) Who are Twins? 150 | SELECT Person.FirstName + ' ' + Person.LastName, 151 | Twin.FirstName + ' ' + Twin.LastName as Twin, 152 | Person.DateOfBirth 153 | FROM Person 154 | JOIN Person Twin 155 | ON Person.PersonID != Twin.PersonID 156 | AND Person.MotherID = Twin.MotherID 157 | AND Person.DateOfBirth = Twin.DateOfBirth 158 | WHERE Person.DateOfBirth IS NOT NULL 159 | 160 | SELECT Person.FirstName + ' ' + Person.LastName, 161 | Twin.FirstName + ' ' + Twin.LastName as Twin, 162 | Person.DateOfBirth 163 | FROM Person 164 | JOIN Person Twin 165 | ON Person.MotherID = Twin.MotherID 166 | WHERE Person.DateOfBirth IS NOT NULL 167 | AND Person.PersonID != Twin.PersonID 168 | AND Person.DateOfBirth = Twin.DateOfBirth 169 | 170 | 171 | ----------------------------------------------------------- 172 | -- 12) Who was born out of wedlock? 173 | 174 | SELECT Person.PersonID, Person.FirstName, Person.LastName, 175 | Person.DateOfBirth 176 | FROM Person 177 | WHERE 178 | PersonID IN ( 179 | SELECT PersonID -- parents at one time married but not at time of birth 180 | FROM Person 181 | JOIN Marriage 182 | ON Person.MotherID = Marriage.WifeID 183 | AND Person.FatherID = Marriage.HusbandID 184 | AND Person.DateOfBirth < Marriage.DateOfWedding 185 | AND (Person.DateOfBirth > Marriage.DateOfDivorce 186 | OR Marriage.DateOfDivorce IS NULL) ) 187 | OR PersonID IN ( 188 | SELECT PersonID -- Mother unmarried 189 | FROM Person 190 | LEFT JOIN Marriage 191 | ON Person.MotherID = Marriage.WifeID 192 | WHERE Marriage.MarriageID IS NULL 193 | AND Person.MotherID IS NOT NULL) 194 | OR PersonID IN ( 195 | SELECT PersonID -- Mother not married to Father (known) 196 | FROM Person 197 | LEFT JOIN Marriage 198 | ON Person.MotherID = Marriage.WifeID 199 | AND Person.FatherID != Marriage.HusbandID 200 | AND Person.DateOfBirth > Marriage.DateOfWedding 201 | AND (Person.DateOfBirth < Marriage.DateOfDivorce 202 | OR Marriage.DateOfDivorce IS NULL) 203 | WHERE MotherID IS NOT NULL 204 | AND FatherID IS NOT NULL 205 | AND Marriage.MarriageID IS NOT NULL ) 206 | 207 | -- Carl's solution 208 | SELECT Person.* 209 | FROM Person 210 | WHERE Person.MotherId IS NOT NULL 211 | AND NOT EXISTS 212 | (SELECT 1 213 | FROM Marriage 214 | WHERE Marriage.WifeId = Person.MotherId 215 | AND Person.DateOfBirth 216 | BETWEEN Marriage.DateOfWedding 217 | AND COALESCE(Marriage.DateOfDivorce,Person.DateOfBirth) 218 | ) 219 | 220 | 221 | ----------------------------------------------------------- 222 | -- 13) How many life events (children, marriages, divorces, deaths) has each woman had? 223 | 224 | SELECT FirstName + ' ' + LastName AS Woman, 225 | IsNull(Marriages,0) AS Marriages, IsNull(Divorces,0) AS Divorces, IsNull(Children,0) AS Children, 226 | IsNull(HusbandDeaths,0) AS HusbandDeaths, IsNull(ChildDeaths,0) AS ChildDeaths, 227 | IsNull(Marriages,0) + IsNull(Divorces,0) + IsNull(Children,0) + 228 | IsNull(HusbandDeaths,0) +IsNull(ChildDeaths,0) AS LifeEvents 229 | FROM Person 230 | LEFT OUTER JOIN 231 | (SELECT WifeID, Count(*) AS Marriages 232 | FROM Marriage 233 | GROUP BY WifeID) M 234 | ON Person.PersonID = M.WifeID 235 | 236 | LEFT OUTER JOIN 237 | (SELECT MotherID, COUNT(*) AS Children 238 | FROM Person 239 | WHERE MotherID IS NOT NULL 240 | GROUP BY MotherID) C 241 | ON Person.PersonID = C.MotherID 242 | 243 | LEFT OUTER JOIN 244 | (SELECT WifeID, Count(*) AS Divorces 245 | FROM Marriage 246 | WHERE DateOfDivorce IS NOT NULL 247 | GROUP BY WifeID) D 248 | ON Person.PersonID = D.WifeID 249 | 250 | LEFT OUTER JOIN 251 | ( SELECT Person.MotherID, Count(*) AS ChildDeaths 252 | FROM Person 253 | JOIN Person M 254 | ON Person.MotherID = M.PersonID 255 | AND Person.DateOfDeath < M.DateOfDeath 256 | GROUP BY Person.MotherID ) CD 257 | ON Person.MotherID = CD.MotherID 258 | 259 | LEFT OUTER JOIN 260 | ( SELECT Person.PersonID, Count(*) AS HusbandDeaths 261 | FROM Person 262 | JOIN Marriage 263 | ON Person.PersonID = Marriage.WifeID 264 | JOIN Person H 265 | ON Marriage.HusbandID = H.PersonID 266 | AND H.DateOfDeath < Person.DateOfDeath 267 | GROUP BY Person.PersonID ) HD 268 | ON Person.MotherID = HD.PersonID 269 | 270 | WHERE Person.Gender = 'F' 271 | ORDER BY LifeEvents DESC 272 | 273 | 274 | ----------------------------------------------------------- 275 | --14) Who are the two patriachs at the top of the family tree? 276 | SELECT Person.FirstName + ' ' + Person.Lastname 277 | FROM Person 278 | WHERE Person.Gender = 'M' 279 | AND Person.MotherID IS NULL 280 | AND Person.FatherID IS NULL 281 | AND PersonID NOT IN -- married a person with a MotherID or FatherID 282 | (SELECT Person.PersonID 283 | FROM Person 284 | JOIN Marriage 285 | ON Person.PersonID = Marriage.HusbandID 286 | JOIN Person Wife 287 | ON Marriage.WifeID = Wife.PersonID 288 | WHERE Wife.MotherID IS NOT NULL 289 | OR Wife.FatherID IS NOT NULL) 290 | 291 | ----------------------------------------------------------- 292 | -- 15) Who married into the Family? Who did they marry? How old were they when they married? 293 | 294 | -- new wife joining to husbands in the family 295 | SELECT Person.FirstName, Person.MaidenName, 296 | H.FirstName + ' ' + H.LastName + ISNULL(' ' + H.SrJr,'') AS Spouse, 297 | CONVERT(VARCHAR(12),HM.DateOfWedding,101) AS Wedding, 298 | DATEDIFF(yy, Person.DateOfBirth, HM.DateOfWedding) AS Age 299 | FROM Person 300 | LEFT JOIN Marriage HM 301 | ON Person.PersonID = HM.WifeID 302 | LEFT JOIN Person H 303 | ON HM.HusbandID = H.PersonID 304 | -- married in has no recorded parents 305 | WHERE Person.FatherID IS NULL 306 | AND Person.MotherID IS NULL 307 | AND HM.MarriageID IS NOT NULL 308 | -- not founder of family 309 | AND Person.PersonID > 4 310 | UNION 311 | -- new husband joining to wives in the family 312 | SELECT Person.FirstName, Person.LastName, 313 | W.FirstName + ' ' + W.LastName , 314 | CONVERT(VARCHAR(12),WM.DateOfWedding,101) , 315 | DATEDIFF(yy, Person.DateOfBirth, WM.DateOfWedding) 316 | FROM Person 317 | -- new wife joining to husbands in the family 318 | LEFT JOIN Marriage WM 319 | ON Person.PersonID = WM.HusbandID 320 | LEFT JOIN Person W 321 | ON WM.WifeID = W.PersonID 322 | -- married in has no recorded parents 323 | WHERE Person.FatherID IS NULL 324 | AND Person.MotherID IS NULL 325 | AND WM.MarriageID IS NOT NULL 326 | -- not founder of family 327 | AND Person.PersonID > 4 328 | ORDER BY Person.FirstName, Person.MaidenName 329 | -------------------------------------------------------------------------------- /Family/Family_UDF.sql: -------------------------------------------------------------------------------- 1 | Use Family 2 | 3 | 4 | go 5 | CREATE 6 | -- alter 7 | FUNCTION dbo.descendents 8 | (@ClassName CHAR(25)) 9 | RETURNS @Classes TABLE (ClassID INT, ClassName VARCHAR(25), Lv INT) 10 | AS 11 | BEGIN 12 | DECLARE @LC INT 13 | SET @LC = 1 14 | -- Handle the Anchor Person 15 | INSERT @Classes 16 | SELECT ClassID, ClassName, @LC 17 | FROM dbo.Class with (NoLock) 18 | WHERE ClassName = @ClassName 19 | 20 | -- Loop through sub-levels 21 | WHILE @@RowCount > 0 22 | BEGIN 23 | SET @LC = @LC + 1 24 | -- insert the Class level 25 | INSERT @Classes 26 | SELECT ClassTree.ClassID, ClassTree.ClassName, @LC 27 | FROM dbo.Class ClassNode with (NoLock) 28 | JOIN dbo.Class ClassTree with (NoLock) 29 | ON ClassNode.ClassID = ClassTree.SuperClassID 30 | JOIN @Classes CC 31 | ON CC.ClassID = ClassNode.ClassID 32 | WHERE CC.Lv = @LC - 1 33 | END 34 | RETURN 35 | END 36 | -------------------------------------------------------------------------------- /Lessons/LESSON_026.SQL: -------------------------------------------------------------------------------- 1 | ----------------------------------------------------------- 2 | -- SQL Server 2017 3 | -- 4 | -- Selecting Data 5 | -- Lesson 26 - Aggregating Data 6 | -- 7 | -- Ahmed Mohamady 8 | ----------------------------------------------------------- 9 | 10 | ----------------------------------------------------------- 11 | -- Using the new Windowing Functions 12 | 13 | Use AdventureWorks2017; 14 | 15 | SELECT ProductID, TransactionDate 16 | FROM Production.TransactionHistory 17 | ORDER BY TransactionDate; 18 | 19 | SELECT ProductID, TransactionDate, 20 | Row_Number() OVER(ORDER BY TransactionDate) as RowNumDate, 21 | Row_Number() OVER(ORDER BY ProductID) + 5000 as RowNumiD 22 | FROM Production.TransactionHistory 23 | -- not permitted 24 | Where Row_Number() OVER(ORDER BY TransactionDate) Between 10001 AND 20000 25 | ORDER BY TransactionDate; 26 | 27 | -- Select mid-range of rownumbers & every 5th row 28 | SELECT RowNum, ProductID, TransactionDate 29 | FROM (SELECT ProductID, TransactionDate, 30 | Row_Number() OVER(ORDER BY TransactionDate) as RowNum 31 | FROM Production.TransactionHistory) sq 32 | WHERE RowNum Between 10001 AND 20000 33 | AND RowNum%5 = 0 34 | ORDER BY RowNum ; 35 | 36 | -- Ranking and Windowing 37 | SELECT SalesOrderId, CustomerId, TerritoryID, 38 | ROW_NUMBER() OVER(ORDER BY CustomerId) AS RowNum, 39 | RANK() OVER(ORDER BY CustomerId) AS [Rank], 40 | DENSE_RANK() OVER(ORDER BY CustomerId) AS [DenseRank], 41 | NTILE(5) OVER(ORDER BY CustomerId) AS NTile5, 42 | RANK() OVER(PARTITION BY TerritoryID ORDER BY CustomerId) AS [Partition] 43 | FROM Sales.SalesOrderHeader; 44 | 45 | -- Percentile Ranking 46 | SELECT SalesOrderId, CustomerId, 47 | NTILE(100) OVER(ORDER BY CustomerId) AS Percentile 48 | FROM Sales.SalesOrderHeader 49 | ORDER BY CustomerId 50 | 51 | -- Sample Data 52 | SELECT 53 | SalesOrderId, CustomerId 54 | FROM Sales.SalesOrderHeader TABLESAMPLE (10000 rows) 55 | 56 | SELECT 57 | SalesOrderId, CustomerId 58 | FROM Sales.SalesOrderHeader TABLESAMPLE (10 percent) 59 | ORDER BY CustomerId -------------------------------------------------------------------------------- /Lessons/LESSON_027.SQL: -------------------------------------------------------------------------------- 1 | ----------------------------------------------------------- 2 | -- SQL Server 2017 3 | -- 4 | -- Selecting Data 5 | -- Lesson 27 - Aggregating Data 6 | -- 7 | -- Ahmed Mohamady 8 | ----------------------------------------------------------- 9 | 10 | ----------------------------------------------------------- 11 | -- Using Aggregate Functions 12 | go 13 | 14 | -- Build the sample data 15 | USE NEW_DB 16 | 17 | IF EXISTS(SELECT * FROM sysobjects WHERE Name = 'RawData') 18 | DROP TABLE RawData 19 | go 20 | 21 | CREATE TABLE RawData ( 22 | Region VARCHAR(10), 23 | Category CHAR(1), 24 | Amount INT, 25 | SalesDate DateTime 26 | ) 27 | 28 | go 29 | 30 | INSERT RawData (Region, Category, Amount, SalesDate) 31 | VALUES( 'South', 'Y', 12, '11/1/2005') 32 | INSERT RawData (Region, Category, Amount, SalesDate) 33 | VALUES( 'South', 'Y', 24, '11/1/2005') 34 | INSERT RawData (Region, Category, Amount, SalesDate) 35 | VALUES( 'South', 'Y', 15, '12/1/2005') 36 | INSERT RawData (Region, Category, Amount, SalesDate) 37 | VALUES( 'NorthEast', 'Y', 28, '12/1/2005') 38 | INSERT RawData (Region, Category, Amount, SalesDate) 39 | VALUES( 'South', 'X', 11, '1/1/2006') 40 | INSERT RawData (Region, Category, Amount, SalesDate) 41 | VALUES( 'MidWest', 'X', 24, '1/1/2006') 42 | INSERT RawData (Region, Category, Amount, SalesDate) 43 | VALUES( 'West', 'X', 36, '2/1/2006') 44 | INSERT RawData (Region, Category, Amount, SalesDate) 45 | VALUES( 'South', 'Y', 47, '2/1/2006') 46 | INSERT RawData (Region, Category, Amount, SalesDate) 47 | VALUES( 'MidWest', 'Y', 38, '3/1/2006') 48 | INSERT RawData (Region, Category, Amount, SalesDate) 49 | VALUES( 'NorthEast', 'Y', 62, '3/1/2006') 50 | INSERT RawData (Region, Category, Amount, SalesDate) 51 | VALUES( 'South', 'Z', 33, '4/1/2006') 52 | INSERT RawData (Region, Category, Amount, SalesDate) 53 | VALUES( 'MidWest', 'Z', 83, '4/1/2006') 54 | INSERT RawData (Region, Category, Amount, SalesDate) 55 | VALUES( 'West', 'Z', 44, '5/1/2006') 56 | INSERT RawData (Region, Category, Amount, SalesDate) 57 | VALUES( 'NorthEast', 'Z', 55, '5/1/2006') 58 | INSERT RawData (Region, Category, Amount, SalesDate) 59 | VALUES( 'South', 'X', 68, '6/1/2006') 60 | INSERT RawData (Region, Category, Amount, SalesDate) 61 | VALUES( 'South', 'X', 86, '6/1/2006') 62 | INSERT RawData (Region, Category, Amount, SalesDate) 63 | VALUES( 'South', 'Y', 54, '7/1/2006') 64 | INSERT RawData (Region, Category, Amount, SalesDate) 65 | VALUES( 'South', 'Y', 63, '7/1/2006') 66 | INSERT RawData (Region, Category, Amount, SalesDate) 67 | VALUES( 'South', 'Y', 72, '8/1/2006') 68 | INSERT RawData (Region, Category, Amount, SalesDate) 69 | VALUES( 'NorthEast', 'Y', 91, '8/1/2006') 70 | INSERT RawData (Region, Category, Amount, SalesDate) 71 | VALUES( 'NorthEast', 'Y', null, '8/1/2006') 72 | INSERT RawData (Region, Category, Amount, SalesDate) 73 | VALUES( 'NorthEast', 'Y', null, '8/1/2006') 74 | INSERT RawData (Region, Category, Amount, SalesDate) 75 | VALUES( 'NorthEast', 'Y', null, '8/1/2006') 76 | INSERT RawData (Region, Category, Amount, SalesDate) 77 | VALUES( 'NorthEast', 'Y', null, '8/1/2006') 78 | 79 | -- check the Amount 80 | SELECT * FROM RawData 81 | 82 | -- Simple Aggregations 83 | SELECT 84 | Count(*) as Count, 85 | Sum(Amount) as [Sum], 86 | Avg(Amount) as [Avg], 87 | Min(Amount) as [Min], 88 | Max(Amount) as [Max] 89 | FROM RawData 90 | 91 | -- How Nulls affect Averages 92 | SELECT Avg(Cast((Amount)as Numeric(9,5))) as [Numeric Avg], 93 | Avg(Amount) as [Int Avg], 94 | Sum(Amount) / Count(*) as [Manual Avg] 95 | FROM RawData 96 | 97 | 98 | 99 | 100 | -- Statistical Functions 101 | -- standard deviation 102 | -- variance 103 | 104 | SELECT 105 | Count(*) as Count, 106 | StDevP(Amount) as [StDevP], 107 | VarP(Amount) as [VarP] 108 | FROM RawData 109 | 110 | SELECT 111 | Count(*) as Count, 112 | StDev(Amount) as [StDev], 113 | Var(Amount) as [Var] 114 | FROM RawData 115 | WHERE Year(SalesDate) = 2006 -------------------------------------------------------------------------------- /Lessons/LESSON_028.SQL: -------------------------------------------------------------------------------- 1 | ----------------------------------------------------------- 2 | -- SQL Server 2017 3 | -- 4 | -- Selecting Data 5 | -- Lesson 28 - Aggregating Data 6 | -- 7 | -- Ahmed Mohamady 8 | ----------------------------------------------------------- 9 | --------------------------------------------- 10 | -- Grouping and Aggregating 11 | 12 | SELECT Category, 13 | Count(*) as Count, 14 | Sum(Amount) as [Sum], 15 | Avg(Amount) as [Avg], 16 | Min(Amount) as [Min], 17 | Max(Amount) as [Max] 18 | FROM RawData 19 | GROUP BY Category 20 | 21 | -- Group by occurs after the where clause 22 | SELECT Category, 23 | Count(*) as Count, 24 | Sum(Amount) as [Sum], 25 | Avg(Amount) as [Avg], 26 | Min(Amount) as [Min], 27 | Max(Amount) as [Max] 28 | FROM RawData 29 | WHERE Year(SalesDate) = 2006 30 | GROUP BY Category 31 | 32 | -- Grouping By multiple columns 33 | SELECT Year(SalesDate) as [Year], DatePart(q,SalesDate) as [Quarter], 34 | Count(*) as Count, 35 | Sum(Amount) as [Sum], 36 | Avg(Amount) as [Avg], 37 | Min(Amount) as [Min], 38 | Max(Amount) as [Max] 39 | FROM RawData 40 | GROUP BY Year(SalesDate), DatePart(q,SalesDate) 41 | 42 | --------------------------------------------- 43 | -- Including Descriptions 44 | 45 | IF EXISTS(SELECT * FROM sysobjects WHERE Name = 'RawCategory') 46 | DROP TABLE RawCategory 47 | 48 | CREATE TABLE RawCategory ( 49 | RawCategoryID CHAR(1), 50 | CategoryName VARCHAR(25) 51 | ) 52 | 53 | INSERT RawCategory (RawCategoryID, CategoryName) 54 | VALUES ('X', 'Sci-Fi') 55 | INSERT RawCategory (RawCategoryID, CategoryName) 56 | VALUES ('Y', 'Philosophy') 57 | INSERT RawCategory (RawCategoryID, CategoryName) 58 | VALUES ('Z', 'Zoology') 59 | 60 | 61 | 62 | 63 | -- including Amount outside the aggregate function or group by will cause an error 64 | /* 65 | SELECT Category, CategoryName, 66 | Sum(Amount) as [Sum], 67 | Avg(Amount) as [Avg], 68 | Min(Amount) as [Min], 69 | Max(Amount) as [Max] 70 | FROM RawData R 71 | JOIN RawCategory C 72 | ON R.Category = C.RawCategoryID 73 | GROUP BY Category 74 | */ 75 | 76 | 77 | -- Solution 1: include all Amount in the Group By 78 | SELECT Category, CategoryName, 79 | Sum(Amount) as [Sum], 80 | Avg(Amount) as [Avg], 81 | Min(Amount) as [Min], 82 | Max(Amount) as [Max] 83 | FROM RawData R 84 | JOIN RawCategory C 85 | ON R.Category = C.RawCategoryID 86 | GROUP BY Category, CategoryName 87 | ORDER BY Category, CategoryName 88 | 89 | -- Solution 2: Aggregate in Subquery, description in outer query 90 | SELECT sq.Category, CategoryName, sq.[Sum], sq.[Avg], sq.[Min], sq.[Max] 91 | FROM (SELECT Category, 92 | Sum(Amount) as [Sum], 93 | Avg(Amount) as [Avg], 94 | Min(Amount) as [Min], 95 | Max(Amount) as [Max] 96 | FROM RawData 97 | GROUP BY Category ) sq 98 | JOIN RawCategory C 99 | ON sq.Category = C.RawCategoryID 100 | ORDER BY Category, CategoryName -------------------------------------------------------------------------------- /Lessons/LESSON_029.SQL: -------------------------------------------------------------------------------- 1 | ----------------------------------------------------------- 2 | -- SQL Server 2017 3 | -- 4 | -- Selecting Data 5 | -- Lesson 29 - Aggregating Data 6 | -- 7 | -- Ahmed Mohamady 8 | ----------------------------------------------------------- 9 | ----------------------------------------------------------- 10 | -- Including all Group By Values 11 | 12 | -- Left Outer Join Group Bys 13 | SELECT Year(SalesDate) AS [Year], 14 | Count(*) as Count, 15 | Sum(Amount) as [Sum], 16 | Avg(Amount) as [Avg], 17 | Min(Amount) as [Min], 18 | Max(Amount) as [Max] 19 | FROM RawData 20 | WHERE Year(SalesDate) = 2006 -- (There are a few 2005 rows in the RawData table) 21 | GROUP BY ALL Year(SalesDate) 22 | 23 | 24 | 25 | ------------------------------------------------------------------ 26 | -- Nesting Aggregations 27 | 28 | -- Which Category sold the most in each quarter? 29 | 30 | -- Can't nest aggregate function - error: 31 | /* 32 | Select Y,Q, Max(Sum) as MaxSum 33 | FROM ( -- Calculate Sums 34 | SELECT Category, Year(SalesDate) as Y, DatePart(q,SalesDate) as Q, max(Sum(Amount)) as Sum 35 | FROM RawData 36 | GROUP BY Category, Year(SalesDate), DatePart(q,SalesDate) 37 | ) sq 38 | GROUP BY Y,Q 39 | ORDER BY Y,Q 40 | */ 41 | 42 | -- Solution: Including Detail description 43 | 44 | SELECT MaxQuery.Y, MaxQuery.Q, AllQuery.Category, MaxQuery.MaxSum as sales 45 | FROM (-- Find Max Sum Per Year/Quarter 46 | Select Y,Q, Max(Sum) as MaxSum 47 | FROM ( -- Calculate Sums 48 | SELECT Category, Year(SalesDate) as Y, DatePart(q,SalesDate) as Q, Sum(Amount) as Sum 49 | FROM RawData 50 | GROUP BY Category, Year(SalesDate), DatePart(q,SalesDate) 51 | ) sq 52 | GROUP BY Y,Q 53 | ) MaxQuery 54 | JOIN (-- All Amount Query 55 | SELECT Category, Year(SalesDate) as Y, DatePart(q,SalesDate) as Q, Sum(Amount) as Sum 56 | FROM RawData 57 | GROUP BY Category, Year(SalesDate), DatePart(q,SalesDate) 58 | )AllQuery 59 | ON MaxQuery.Y = AllQuery.Y 60 | AND MaxQuery.Q = AllQuery.Q 61 | AND MaxQuery.MaxSum = AllQuery.Sum 62 | ORDER BY MaxQuery.Y, MaxQuery.Q 63 | 64 | 65 | 66 | --------------------------------------------- -------------------------------------------------------------------------------- /Lessons/LESSON_030.SQL: -------------------------------------------------------------------------------- 1 | ----------------------------------------------------------- 2 | -- SQL Server 2017 3 | -- 4 | -- Selecting Data 5 | -- Lesson 30 - Aggregating Data 6 | -- 7 | -- Ahmed Mohamady 8 | -------------------------------------------------------- 9 | 10 | -------------------------------------------------------- 11 | -- Adding Grand Totals 12 | 13 | -- Sum of single column Group By (Roll-Up) 14 | SELECT Grouping(Category), Category, 15 | CASE Grouping(Category) 16 | WHEN 0 THEN Category 17 | WHEN 1 THEN 'All Categories' 18 | END AS Category, 19 | Count(*) as Count 20 | FROM RawData 21 | GROUP BY Category 22 | WITH ROLLUP 23 | 24 | -- Sum of Mulitple column Group By (Roll-Up) 25 | -- Second Group by Column w/ subtotals 26 | 27 | SELECT 28 | CASE Grouping(Category) 29 | WHEN 0 THEN Category 30 | WHEN 1 THEN 'All Categories' 31 | END AS Category, 32 | CASE Grouping(Year(SalesDate)) 33 | WHEN 0 THEN Cast(Year(SalesDate) as CHAR(8)) 34 | WHEN 1 THEN 'All Years' 35 | END AS Year, 36 | Count(*) as Count 37 | FROM RawData 38 | GROUP BY Category, Year(SalesDate) 39 | WITH ROLLUP 40 | 41 | -- Multidimensional column Group By (Cube) 42 | SELECT 43 | CASE Grouping(Category) 44 | WHEN 0 THEN Category 45 | WHEN 1 THEN 'All Categories' 46 | END AS Category, 47 | CASE Grouping(Year(SalesDate)) 48 | WHEN 0 THEN Cast(Year(SalesDate) as CHAR(8)) 49 | WHEN 1 THEN 'All Years' 50 | END AS Year, Count(*) as Count 51 | FROM RawData 52 | GROUP BY Category, Year(SalesDate) 53 | WITH CUBE 54 | -------------------------------------------------------------------------------- /Lessons/LESSON_031.SQL: -------------------------------------------------------------------------------- 1 | ----------------------------------------------------------- 2 | -- SQL Server 2017 3 | -- 4 | -- Selecting Data 5 | -- Lesson 31 - Aggregating Data 6 | -- 7 | -- Ahmed Mohamady 8 | -------------------------------------------------------- 9 | ------------------------------------------------------------------- 10 | -- Generating Crosstab(Pivot) Tables 11 | 12 | -- Fixed Column CrossTab with Category Subtotal- CASE Method 13 | SELECT Category, 14 | SUM(Case Region WHEN 'South' THEN Amount ELSE 0 END) AS South, 15 | SUM(Case Region WHEN 'NorthEast' THEN Amount ELSE 0 END) AS NorthEast, 16 | SUM(Case Region WHEN 'MidWest' THEN Amount ELSE 0 END) AS MidWest, 17 | SUM(Case Region WHEN 'West' THEN Amount ELSE 0 END) AS West, 18 | SUM(Amount) as Total 19 | FROM RawData 20 | GROUP BY Category 21 | ORDER BY Category 22 | 23 | 24 | -- Fixed Column Crosstab - PIVOT Method 25 | SELECT Category, SalesDate, South, NorthEast, MidWest, West 26 | FROM RawData 27 | PIVOT 28 | (Sum (Amount) 29 | FOR Region IN (South, NorthEast, MidWest, West) 30 | ) AS pt 31 | 32 | SELECT Category, South, NorthEast, MidWest, West 33 | FROM (Select Category, Region, Amount from RawData) sq 34 | PIVOT 35 | (Sum (Amount) 36 | FOR Region IN (South, NorthEast, MidWest, West) 37 | ) AS pt 38 | 39 | 40 | -- Fixed Column Crosstab with Category Subtotal - PIVOT Method 41 | SELECT Category, South, NorthEast, MidWest, West, 42 | IsNull(South,0) + IsNull(NorthEast,0) + IsNull(MidWest,0) + IsNull(West,0) as Total 43 | FROM (Select Category, Region, Amount from RawData) sq 44 | PIVOT 45 | (Sum (Amount) 46 | FOR Region IN (South, NorthEast, MidWest, West) 47 | ) AS pt 48 | 49 | -- Fixed Column Crosstab with Filter - PIVOT Method 50 | -- Must filter within the FROM clause (using subquery) prior to Pivot operation 51 | SELECT Category, South, NorthEast, MidWest, West, 52 | IsNull(South,0) + IsNull(NorthEast,0) + IsNull(MidWest,0) + IsNull(West,0) as Total 53 | FROM (Select Region, Category, Amount 54 | From RawData 55 | Where Category = 'Z') sq 56 | PIVOT 57 | (Sum (Amount) 58 | FOR Region IN (South, NorthEast, MidWest, West) 59 | ) AS pt 60 | 61 | -- Dynamic CrossTabs with Multiple Assignment Variable and Pivot Method 62 | -- Appending to a variable within a query to dynamically generate the column names 63 | 64 | DECLARE @SQLStr NVARCHAR(1024) 65 | SET @SQLStr = '' 66 | SELECT @SQLStr = @SQLStr + [a].[Column] + ', ' 67 | FROM 68 | (SELECT DISTINCT Region as [Column] 69 | FROM RawData ) as a 70 | 71 | SET @SQLStr = Left(@SQLStr, Len(@SQLStr) - 1) 72 | 73 | SET @SQLStr = 'SELECT Category, ' 74 | + @SQLStr 75 | + ' FROM (Select Category, Region, Amount from RawData) sq PIVOT (Sum (Amount) FOR Region IN (' 76 | + @SQLStr 77 | + ')) AS pt' 78 | PRINT @SQLStr 79 | 80 | EXEC sp_executesql @SQLStr 81 | 82 | --------------------------------------------------------------- -------------------------------------------------------------------------------- /Lessons/LESSON_032.SQL: -------------------------------------------------------------------------------- 1 | ----------------------------------------------------------- 2 | -- SQL Server 2017 3 | -- 4 | -- Selecting Data 5 | -- Lesson 32 - Using Full-Text Search 6 | -- 7 | -- Ahmed Mohamady 8 | -------------------------------------------------------- 9 | ----------------------------------------------------------- 10 | -- Creating a Full-Text Index 11 | 12 | USE AESOP 13 | 14 | -- SQL Where Like 15 | SELECT Title 16 | FROM Fable 17 | WHERE Fabletext LIKE '%lion%' 18 | AND Fabletext LIKE '%bold%' 19 | 20 | CREATE FULLTEXT CATALOG AesopFT 21 | 22 | CREATE FULLTEXT INDEX ON dbo.Fable(Title, Moral, Fabletext) 23 | KEY INDEX FablePK ON AesopFT 24 | WITH CHANGE_TRACKING AUTO 25 | GO 26 | 27 | 28 | ----------------------------------------------------- 29 | -- Searching for Words 30 | 31 | -- Contains 32 | SELECT Title 33 | FROM Fable 34 | WHERE CONTAINS (Fable.*,'Lion') 35 | 36 | -------------------------------------------------------------------------------- /Lessons/LESSON_033.SQL: -------------------------------------------------------------------------------- 1 | ----------------------------------------------------------- 2 | -- SQL Server 2017 3 | -- 4 | -- Selecting Data 5 | -- Lesson 33 - Using Full-Text Search 6 | -- 7 | -- Ahmed Mohamady 8 | -------------------------------------------------------- 9 | ----------------------------------------------------- 10 | -- Searching for Words 11 | 12 | USE AESOP 13 | 14 | -- Contains 15 | SELECT Title 16 | FROM Fable 17 | WHERE CONTAINS (Fable.*,'Lion') 18 | 19 | -- Joining with Full-Text Search 20 | SELECT * 21 | FROM CONTAINSTABLE (Fable, *, 'Lion') 22 | 23 | SELECT Fable.Title, Rank 24 | FROM Fable 25 | JOIN CONTAINSTABLE (Fable, *, 'Lion') FTS 26 | ON Fable.FableID = FTS.[KEY] 27 | ORDER BY FTS.Rank DESC 28 | 29 | SELECT Fable.Title, Rank 30 | FROM Fable 31 | JOIN CONTAINSTABLE (Fable, *, 'Lion', 2) FTS 32 | ON Fable.FableID = FTS.[KEY] 33 | ORDER BY FTS.Rank 34 | 35 | -- Advanced Options 36 | 37 | -- Phrases 38 | SELECT Title 39 | FROM Fable 40 | WHERE CONTAINS (*,' "Wolf! Wolf!" ') 41 | 42 | -- Or, And 43 | SELECT Title 44 | FROM Fable 45 | WHERE CONTAINS (FableText,'Tortoise AND Hare') 46 | 47 | SELECT Title 48 | FROM Fable 49 | WHERE CONTAINS (*,' "Thrifty AND supperless" ') 50 | 51 | SELECT Title 52 | FROM Fable 53 | WHERE CONTAINS (*,'Thrifty') 54 | AND CONTAINS(*,'supperless') 55 | 56 | -- Wildcards * 57 | SELECT Title 58 | FROM Fable 59 | WHERE CONTAINS (*,' "Hunt*" ') 60 | 61 | -- Near 62 | SELECT Title 63 | FROM Fable 64 | WHERE CONTAINS (*,'pardoned NEAR forest') 65 | 66 | SELECT Title 67 | FROM Fable 68 | WHERE CONTAINS (*,'lion NEAR paw NEAR bleeding') 69 | 70 | SELECT Fable.Title, Rank 71 | FROM Fable 72 | JOIN CONTAINSTABLE (Fable, *,'life NEAR death') FTS 73 | ON Fable.FableID = FTS.[KEY] 74 | ORDER BY FTS.Rank DESC 75 | 76 | -- Weighting 77 | SELECT Fable.Title, FTS.Rank 78 | FROM Fable 79 | JOIN CONTAINSTABLE (Fable, fabletext, 'ISABOUT (Lion weight (.5), Brave weight (.5), Eagle weight (.5))',20) FTS 80 | ON Fable.FableID = FTS.[KEY] 81 | ORDER BY Rank DESC 82 | 83 | SELECT Fable.Title, FTS.Rank 84 | FROM Fable 85 | JOIN CONTAINSTABLE (Fable, fabletext, 'ISABOUT (Lion weight (.2), Brave weight (.2), Eagle weight (.8))',20) FTS 86 | ON Fable.FableID = FTS.[KEY] 87 | ORDER BY Rank DESC 88 | 89 | SELECT Fable.Title, FTS.Rank 90 | FROM Fable 91 | JOIN CONTAINSTABLE (Fable, *, 'ISABOUT (Lion weight (.2), Brave weight (.2), Eagle weight (.8))',20) FTS 92 | ON Fable.FableID = FTS.[KEY] 93 | ORDER BY Rank DESC 94 | 95 | -- Inflection 96 | SELECT Title 97 | FROM Fable 98 | WHERE CONTAINS (*,'FORMSOF(INFLECTIONAL,pity)') 99 | 100 | SELECT Title 101 | FROM Fable 102 | WHERE CONTAINS (*,'FORMSOF(INFLECTIONAL,geese)') 103 | 104 | SELECT Title 105 | FROM Fable 106 | WHERE CONTAINS (*,'FORMSOF(INFLECTIONAL,carry)') 107 | 108 | SELECT Title 109 | FROM Fable 110 | WHERE CONTAINS (*,'FORMSOF(INFLECTIONAL,fly)') 111 | -------------------------------------------------------------------------------- /Lessons/LESSON_034.SQL: -------------------------------------------------------------------------------- 1 | ----------------------------------------------------------- 2 | -- SQL Server 2017 3 | -- 4 | -- Selecting Data 5 | -- Lesson 34 - Using Full-Text Search 6 | -- 7 | -- Ahmed Mohamady 8 | -------------------------------------------------------- 9 | ---------------------------------------------------- 10 | -- Using Fuzzy Searches 11 | 12 | -- FreeText 13 | 14 | SELECT Title 15 | FROM Fable 16 | WHERE FREETEXT (*,'The Tortoise beat the Hare in the big race') 17 | 18 | SELECT Title 19 | FROM Fable 20 | WHERE FREETEXT (*,'The eagle was shot by an arrow') 21 | 22 | SELECT Title 23 | FROM Fable 24 | WHERE FREETEXT (*,'The brave hunter kills the lion') 25 | 26 | -- FreeText Table 27 | 28 | SELECT Fable.Title, FTS.Rank 29 | FROM Fable 30 | JOIN FREETEXTTABLE (Fable, *, 'The brave hunter kills the lion',20) FTS 31 | ON Fable.FableID = FTS.[KEY] 32 | ORDER BY Rank DESC 33 | 34 | SELECT Fable.Title, FTS.Rank 35 | FROM Fable 36 | JOIN FREETEXTTABLE (Fable, *, 'The eagle was shot by an arrow',20) FTS 37 | ON Fable.FableID = FTS.[KEY] 38 | ORDER BY Rank DESC -------------------------------------------------------------------------------- /Lessons/LESSON_035.SQL: -------------------------------------------------------------------------------- 1 | ----------------------------------------------------------- 2 | -- SQL Server 2017 3 | -- 4 | -- Selecting Data 5 | -- Lesson 35 - Selecting Data through Views 6 | -- 7 | -- Ahmed Mohamady 8 | -------------------------------------------------------- 9 | -- Creating the View 10 | USE [OBXKites] 11 | GO 12 | 13 | IF EXISTS(SELECT * FROM SysObjects WHERE Name = 'ViewFirst') 14 | DROP VIEW dbo.ViewFirst 15 | 16 | 17 | CREATE VIEW [dbo].[ViewFirst] 18 | AS 19 | SELECT O.OrderID AS musterO, O.OrderNumber, O.ContactID, O.OrderPriorityID, 20 | O.EmployeeID, O.LocationID, O.OrderDate, O.Closed, 21 | OD.OrderDetailID, OD.NonStockProduct, OD.UnitPrice, P.ProductID, 22 | P.ProductCategoryID, P.Code, P.ProductName, P.ProductDescription 23 | FROM dbo.Product AS P INNER JOIN 24 | dbo.OrderDetail AS OD ON P.ProductID = OD.ProductID INNER JOIN 25 | dbo.[Order] AS O ON OD.OrderID = O.OrderID 26 | ORDER BY musterO 27 | GO 28 | 29 | 30 | -- Where 31 | Select * From ViewFirst where 32 | OrderNumber = '4' 33 | 34 | 35 | -- Order By 36 | Select * From ViewFirst 37 | Order By [musterO], [OrderNumber] -------------------------------------------------------------------------------- /Lessons/LESSON_036.SQL: -------------------------------------------------------------------------------- 1 | ----------------------------------------------------------- 2 | -- SQL Server 2017 3 | -- 4 | -- Selecting Data 5 | -- Lesson 36 - Selecting Data through Views 6 | -- 7 | -- Ahmed Mohamady 8 | -------------------------------------------------------- 9 | ----------------------------------------------------------- 10 | -- Protecting from Schema Changes 11 | 12 | -- With Schema Binding 13 | 14 | Use [NEW_DB] 15 | go 16 | IF EXISTS(SELECT * FROM SysObjects WHERE Name = 'vTest') 17 | DROP View dbo.vTest 18 | go 19 | IF EXISTS(SELECT * FROM SysObjects WHERE Name = 'Test') 20 | DROP TABLE dbo.Test 21 | 22 | go 23 | CREATE TABLE dbo.Test ( 24 | [Name] NVARCHAR(50) 25 | ) 26 | go 27 | 28 | CREATE VIEW dbo.vTest 29 | WITH SCHEMABINDING 30 | AS 31 | SELECT [Name] FROM dbo.Test 32 | 33 | go 34 | ALTER TABLE dbo.Test 35 | ALTER COLUMN [Name] NVARCHAR(100) 36 | -------------------------------------------------------------------------------- /Lessons/LESSON_037.SQL: -------------------------------------------------------------------------------- 1 | ----------------------------------------------------------- 2 | -- SQL Server 2017 3 | -- 4 | -- Selecting Data 5 | -- Lesson 37 - Modifying Data 6 | -- 7 | -- Ahmed Mohamady 8 | -------------------------------------------------------- 9 | ----------------------------------------------------------- 10 | -- Inserting Data 11 | 12 | USE NEW_DB; 13 | 14 | 15 | CREATE TABLE [dbo].[Guide]( 16 | [Index] [int] IDENTITY(1,1) NOT NULL, 17 | [FirstName] [varchar](50) NULL, 18 | [LastName] [varchar](50) NULL, 19 | [Qualifications] [varchar](50) NULL 20 | ) ON [PRIMARY] 21 | 22 | -- INSERT/VALUES 23 | INSERT INTO dbo.Guide (LastName, FirstName, Qualifications) 24 | VALUES ('Smith', 'Dan', 'Diver, Whitewater Rafting'); 25 | 26 | INSERT INTO dbo.Guide (FirstName, LastName, Qualifications) 27 | VALUES ('Jeff', 'Davis', 'Marine Biologist, Diver'); 28 | 29 | INSERT INTO dbo.Guide (FirstName, LastName) 30 | VALUES ('Tammie', 'Commer'); 31 | 32 | SELECT * from dbo.Guide; 33 | 34 | -- INSERT/VALUES without a insert column listing 35 | INSERT dbo.Guide 36 | VALUES ('Jones', 'Lauren', 'First Aid, Rescue/Extraction'); 37 | 38 | SELECT GuideID, LastName, FirstName, Qualifications 39 | FROM dbo.Guide; 40 | 41 | 42 | -- INSERT/VALUES w/ expression 43 | INSERT dbo.Guide (FirstName, LastName, Qualifications) 44 | VALUES ('Greg', 'Wilson' , 'Rock Climbing' + ', ' + 'First Aid'); 45 | 46 | SELECT * from dbo.Guide; 47 | 48 | 49 | -- INSERT/SELECT 50 | 51 | USE OBXKites; 52 | -- Using a fresh copy of OBXKites without population 53 | 54 | --(Corrected from the text - added ContactCode) 55 | INSERT dbo.Contact (FirstName, ContactCode, LastName, CompanyName) 56 | SELECT FirstName, LastName, GuideID, 'Cape Hatteras Adv.' 57 | FROM NEW_DB.dbo.Guide; 58 | 59 | SELECT ContactID, FirstName AS FIRST, LastName AS LAST , CompanyName 60 | FROM dbo.Contact; 61 | -------------------------------------------------------------------------------- /Lessons/LESSON_038.SQL: -------------------------------------------------------------------------------- 1 | ----------------------------------------------------------- 2 | -- SQL Server 2017 3 | -- 4 | -- Selecting Data 5 | -- Lesson 38 - Modifying Data 6 | -- 7 | -- Ahmed Mohamady 8 | -------------------------------------------------------- 9 | ----------------------------------------------------------- 10 | -- Inserting Data 02 11 | 12 | -- INSERT/Exec 13 | 14 | Use NEW_DB 15 | Go 16 | -- create the sample stored procedure 17 | CREATE PROC ListGuides 18 | AS 19 | SET NOCOUNT ON 20 | 21 | -- result set 1 22 | SELECT FirstName, LastName 23 | FROM dbo.Guide; 24 | 25 | -- result set 2 26 | SELECT FirstName, LastName 27 | FROM dbo.Contact 28 | RETURN; -- end of sproc 29 | go 30 | 31 | -- test the sample stored procedure 32 | Exec ListGuides; 33 | 34 | go 35 | -- create a table for the insert 36 | CREATE TABLE dbo.GuideSample 37 | (FirstName VARCHAR(20), 38 | LastName VARCHAR(20) ); 39 | 40 | -- the insert / exec statement 41 | INSERT GuideSample ( FirstName, LastName) 42 | EXEC ListGuides; 43 | 44 | -- check to see that the insert worked 45 | SELECT * FROM GuideSample; 46 | 47 | -- SELECT INTO 48 | USE NEW_DB; 49 | 50 | -- sample code for setting the bulk-logged behavior 51 | Alter DATABASE NEW_DB SET RECOVERY FULL 52 | EXEC SP_DBOPTION 'NEW_DB', 'select into/bulkcopy', 'TRUE'; 53 | go 54 | 55 | -- the select/into statement 56 | SELECT * INTO dbo.GuideList 57 | FROM dbo.Guide 58 | ORDER BY Lastname, FirstName; 59 | 60 | Go 61 | -- viewing the data structure of the new table 62 | sp_help GuideList; 63 | 64 | --testing the identity column of the new table 65 | INSERT dbo.Guidelist (LastName, FirstName, Qualifications) 66 | VALUES('Nielsen', 'Paul','trainer'); 67 | 68 | SELECT GuideID, LastName, FirstName 69 | FROM dbo.GuideList; 70 | 71 | -- INSERTing Identity Column Primary Keys 72 | USE NEW_DB; 73 | 74 | INSERT dbo.Guide (GuideID, FirstName, LastName) 75 | VALUES (10, 'Bill', 'Wilson'); 76 | 77 | SET IDENTITY_INSERT Guide On; 78 | 79 | INSERT dbo.Guide (GuideID, FirstName, LastName) 80 | VALUES (10, 'Bill', 'Wilson'); 81 | 82 | INSERT dbo.Guide (GuideID, FirstName, LastName) 83 | VALUES (7, 'Sue', 'Atlas'); 84 | 85 | SET IDENTITY_INSERT Guide Off; 86 | 87 | INSERT dbo.Guide ( FirstName, LastName) 88 | VALUES ( 'Arnold', 'Bistier'); 89 | 90 | SELECT GuideID, FirstName, LastName from dbo.Guide; -------------------------------------------------------------------------------- /Lessons/LESSON_039.SQL: -------------------------------------------------------------------------------- 1 | ----------------------------------------------------------- 2 | -- SQL Server 2017 3 | -- 4 | -- Selecting Data 5 | -- Lesson 39 - Modifying Data 6 | -- 7 | -- Ahmed Mohamady 8 | -------------------------------------------------------- 9 | ----------------------------------------------------------- 10 | -- Updating Data 11 | 12 | -- Updating a single column of a single row 13 | USE NEW_DB 14 | UPDATE dbo.Guide 15 | SET Qualifications = 'Spelunking, Cave Diving, Rock Climbing, First Aid, Navigation' 16 | Where GuideID = 6; 17 | 18 | SELECT GuideID, LastName, Qualifications 19 | FROM dbo.Guide 20 | WHERE GuideID = 6; 21 | 22 | -- Global Search and Replace 23 | 24 | USE Family; 25 | 26 | UPDATE Person 27 | SET LastName = REPLACE(Lastname, 'll', 'qua'); 28 | 29 | SELECT lastname 30 | FROM Person; 31 | 32 | 33 | -- A complex update with expression 34 | 35 | USE NEW_DB; 36 | 37 | CREATE TABLE dbo.Dept ( 38 | DeptID INT IDENTITY NOT NULL PRIMARY KEY NONCLUSTERED, 39 | DeptName VARCHAR(50) NOT NULL, 40 | RaiseFactor NUMERIC(4,2) 41 | ) 42 | ON [Primary]; 43 | go 44 | 45 | Create TABLE dbo.Employee ( 46 | EmployeeID INT IDENTITY NOT NULL PRIMARY KEY NONCLUSTERED, 47 | DeptID INT FOREIGN KEY REFERENCES Dept, 48 | LastName VARCHAR(50) NOT NULL, 49 | FirstName VARCHAR(50) NOT NULL, 50 | Salary INT, 51 | PerformanceRating NUMERIC(4,2), 52 | DateHire DATETIME, 53 | DatePosition DATETIME 54 | ) 55 | ON [Primary]; 56 | go 57 | -- build the sample data 58 | INSERT dbo.Dept VALUES ('Engineering', 1.2); 59 | INSERT dbo.Dept VALUES ('Sales',.8); 60 | INSERT dbo.Dept VALUES ('IT',2.5); 61 | INSERT dbo.Dept VALUES ('Manufacturing',1.0); 62 | go 63 | INSERT dbo.Employee VALUES( 1, 'Smith', 'Sam', 54000, 2.0, '1/1/97', '4/1/2001' ); 64 | INSERT dbo.Employee VALUES( 1, 'Nelson', 'Slim', 78000, 1.5, '9/1/88', '1/1/2000' ); 65 | INSERT dbo.Employee VALUES( 2, 'Ball', 'Sally', 45000, 3.5, '2/1/99', '1/1/2001' ); 66 | INSERT dbo.Employee VALUES( 2, 'Kelly', 'Jeff', 85000, 2.4, '10/1/83','9/1/1998' ); 67 | INSERT dbo.Employee VALUES( 3, 'Guelzow', 'Dave', 120000, 4.0, '7/1/95', '6/1/2001' ); 68 | INSERT dbo.Employee VALUES( 3, 'Cliff', 'Melissa', 95000, 1.8, '2/1/99', '9/1/1997' ); 69 | INSERT dbo.Employee VALUES( 4, 'Reagan', 'Frankie', 75000, 2.9, '4/1/00', '4/1/2000' ); 70 | INSERT dbo.Employee VALUES( 4, 'Adams', 'Hank', 34000, 3.2, '9/1/98', '9/1/1998' ); 71 | go 72 | 73 | -- assume raise date is 5/1/2002 74 | SELECT * from dbo.Dept; 75 | SELECT * from dbo.Employee; 76 | 77 | -- test required data 78 | SELECT LastName, Salary, 79 | DateDiff(yy, DateHire, '5/1/2002') as YearsCompany, 80 | DateDiff(mm, DatePosition, '5/1/2002') as MonthPosition, 81 | CASE 82 | WHEN Employee.PerformanceRating >= 2 THEN Employee.PerformanceRating 83 | ELSE 0 84 | END as Performance, 85 | Dept.RaiseFactor 86 | FROM dbo.Employee 87 | JOIN dbo.Dept 88 | ON Employee.DeptID = Dept.DeptID; 89 | 90 | -- Test the raise amount 91 | SELECT LastName, 92 | (2 + (((DateDiff(yy, DateHire, '5/1/2002') * .1) 93 | + (DateDiff(mm, DatePosition, '5/1/2002') * .02) 94 | + (CASE 95 | WHEN Employee.PerformanceRating >= 2 THEN Employee.PerformanceRating 96 | ELSE 0 97 | END * .5 )) 98 | * Dept.RaiseFactor))/100 as EmpRaise 99 | FROM dbo.Employee 100 | JOIN dbo.Dept 101 | ON Employee.DeptID = Dept.DeptID; 102 | 103 | -- Perform the Update 104 | Update Employee Set Salary = Salary * (1 + 105 | (2 + (((DateDiff(yy, DateHire, '5/1/2002') * .1) 106 | + (DateDiff(mm, DatePosition, '5/1/2002') * .02) 107 | + (CASE 108 | WHEN Employee.PerformanceRating >= 2 THEN Employee.PerformanceRating 109 | ELSE 0 110 | END * .5 )) 111 | * Dept.RaiseFactor))/100 ) 112 | FROM dbo.Employee 113 | JOIN dbo.Dept 114 | ON Employee.DeptID = Dept.DeptID; 115 | 116 | 117 | SELECT FirstName, LastName, Salary 118 | FROM dbo.Employee; 119 | Go 120 | 121 | Drop Table dbo.Employee; 122 | Go 123 | Drop table dbo.Dept ; -------------------------------------------------------------------------------- /Lessons/LESSON_040.SQL: -------------------------------------------------------------------------------- 1 | ----------------------------------------------------------- 2 | -- SQL Server 2017 3 | -- 4 | -- Selecting Data 5 | -- Lesson 40 - Modifying Data 6 | -- 7 | -- Ahmed Mohamady 8 | -------------------------------------------------------- 9 | ----------------------------------------------------------- 10 | -- Deleting Data 11 | 12 | USE OBXKites; 13 | 14 | DELETE FROM OBXKites.dbo.Product; 15 | -- w/o WHERE clause deletes all rows 16 | 17 | DELETE FROM dbo.Product 18 | WHERE ProductID = 'DB8D8D60-76F4-46C3-90E6-A8648F63C0F0'; 19 | 20 | -- delete all the product in the books category 21 | DELETE Product 22 | FROM dbo.Product 23 | JOIN ProductCategory 24 | ON Product.ProductCategoryID 25 | = ProductCategory.ProductCategoryID 26 | WHERE ProductcategoryName = 'Video'; 27 | 28 | -- Building a foreign key with referential integrity that cascades deletes 29 | USE [NEW_DB]; 30 | 31 | CREATE TABLE dbo.Event_mm_Guide ( 32 | EventGuideID INT IDENTITY NOT NULL PRIMARY KEY NONCLUSTERED, 33 | GuideID INT NOT NULL 34 | FOREIGN KEY REFERENCES dbo.Guide ON DELETE CASCADE, 35 | LastName VARCHAR(50) NOT NULL, 36 | ) 37 | ON [Primary]; 38 | go 39 | 40 | 41 | --ANSI Standard alternative to Delete From 42 | Use [NORTHWND] 43 | 44 | DELETE FROM Orders WHERE NOT EXISTS (SELECT * 45 | FROM [dbo].[Order Details] b 46 | WHERE 47 | Orders.[OrderID] = b.[OrderID] 48 | AND 49 | Orders.[OrderID] = 10248 50 | ); 51 | 52 | 53 | -- Truncate Table 54 | TRUNCATE TABLE dbo.InventoryTransaction; 55 | -------------------------------------------------------------------------------- /Lessons/LESSON_041.SQL: -------------------------------------------------------------------------------- 1 | ----------------------------------------------------------- 2 | -- SQL Server 2017 3 | -- 4 | -- Selecting Data 5 | -- Lesson 41 - Modifying Data 6 | -- 7 | -- Ahmed Mohamady 8 | -------------------------------------------------------- 9 | ----------------------------------------------------------- 10 | -- Using the Output clause 11 | 12 | USE [NEW_DB] 13 | 14 | INSERT dbo.Guide (LastName, FirstName, Qualifications) 15 | OUTPUT Inserted.* 16 | VALUES('Nielsen', 'Paul', 'diver'); 17 | 18 | UPDATE dbo.Guide 19 | SET Qualifications = 'Scuba' 20 | OUTPUT Deleted.Qualifications as OldQuals, Inserted.Qualifications as NewQuals 21 | Where [Index] = 3; 22 | 23 | -- with table variable 24 | DECLARE @DeletedGuides TABLE ( 25 | GuideID INT, 26 | LastName VARCHAR(50), 27 | FirstName VARCHAR(50) 28 | ); 29 | 30 | DELETE dbo.Guide 31 | OUTPUT Deleted.[Index], Deleted.LastName, Deleted.FirstName 32 | INTO @DeletedGuides 33 | WHERE [Index] = 2; 34 | 35 | SELECT * FROM @DeletedGuides; 36 | 37 | -------------------------------------------------------------------------------- /Lessons/LESSON_042.SQL: -------------------------------------------------------------------------------- 1 | ----------------------------------------------------------- 2 | -- SQL Server 2017 3 | -- 4 | -- Developing Solutions 5 | -- Lesson 42 - T-SQL and Stored Procedures 6 | -- 7 | -- Ahmed Mohamady 8 | ----------------------------------------------------------- 9 | ----------------------------------------------------------- 10 | -- Introducing T-SQL 11 | 12 | -- the is an ANSI style comment 13 | USE Family; 14 | 15 | Select FirstName, LastName -- selects the columns 16 | FROM Person -- the source table 17 | Where LastName Like 'Hal%'; -- the row restriction 18 | 19 | -- C style comments 20 | /* 21 | Order table Insert Trigger 22 | Paul Nielsen 23 | ver 1.0 July 21, 2006 24 | Logic: etc. 25 | ver 1.1: July 31, 2006, added xyz 26 | */ 27 | 28 | -- Debug Commands 29 | Select 3; 30 | Print 6; 31 | 32 | Print 'Begining'; 33 | waitfor delay '00:00:02'; 34 | Print 'Done'; 35 | 36 | ------------------------------------------------- 37 | -- Working with Variables 38 | 39 | -- Variable Default and Scope 40 | DECLARE @Test INT, 41 | @TestTwo NVARCHAR(25); 42 | SELECT @Test, @TestTwo ; 43 | 44 | SET @Test = 1; 45 | SET @TestTwo = 'a value'; 46 | SELECT @Test, @TestTwo; 47 | go --terminates the variables 48 | 49 | SELECT @Test as BatchTwo, @TestTwo; 50 | 51 | -- Using the Set and Select Commands 52 | USE Family 53 | 54 | -- multiple rows & multiple columns 55 | Declare @TempID INT, 56 | @TempLastName VARCHAR(25); 57 | SET @TempID = 99 58 | SELECT @TempID = PersonID, 59 | @TempLastName = LastName 60 | FROM Person 61 | ORDER BY PersonID 62 | SELECT @TempID, @TempLastName; 63 | 64 | -- No rows returned 65 | Declare @TempID INT, 66 | @TempLastName VARCHAR(25); 67 | SET @TempID = 99; 68 | SELECT @TempID = PersonID, 69 | @TempLastName = LastName 70 | FROM Person 71 | WHERE PersonID = 100 72 | ORDER BY PersonID; 73 | SELECT @TempID, @TempLastName; 74 | 75 | -- Using Variables Within SQL Queries 76 | USE OBXKites; 77 | 78 | DECLARE @ProductCode CHAR(10); 79 | SET @ProductCode = '1001'; 80 | 81 | SELECT ProductName 82 | FROM Product 83 | WHERE Code = @ProductCode; 84 | -------------------------------------------------------------------------------- /Lessons/LESSON_043.SQL: -------------------------------------------------------------------------------- 1 | ----------------------------------------------------------- 2 | -- SQL Server 2017 3 | -- 4 | -- Developing Solutions 5 | -- Lesson 43 - T-SQL and Stored Procedures 6 | -- 7 | -- Ahmed Mohamady 8 | ----------------------------------------------------------- 9 | --------------------------------------------------------- 10 | -- Controlling Procedural Flow 11 | 12 | -- If 13 | IF 1 = 0 14 | PRINT 'Line One'; 15 | PRINT 'Line Two'; 16 | 17 | -- If w/ begin/end block 18 | IF 1 = 0 19 | BEGIN 20 | PRINT 'Line One'; 21 | PRINT 'Line Two'; 22 | END 23 | 24 | -- IF Exists() 25 | USE OBXKITES; 26 | IF EXISTS(SELECT * FROM [ORDER] WHERE Closed = 0) 27 | BEGIN; 28 | PRINT 'Process Orders'; 29 | END; 30 | 31 | -- While 32 | DECLARE @Temp int; 33 | SET @Temp = 0; 34 | 35 | WHILE @Temp <3 36 | BEGIN; 37 | PRINT 'tested condition' + Str(@Temp); 38 | SET @Temp = @Temp + 1; 39 | END; 40 | 41 | -- goto 42 | GOTO ErrorHandler; 43 | PRINT 'more code'; 44 | ErrorHandler:; 45 | PRINT 'Logging the error'; 46 | -------------------------------------------------------------------------------- /Lessons/LESSON_044.SQL: -------------------------------------------------------------------------------- 1 | ----------------------------------------------------------- 2 | -- SQL Server 2017 3 | -- 4 | -- Developing Solutions 5 | -- Lesson 44 - T-SQL and Stored Procedures 6 | -- 7 | -- Ahmed Mohamady 8 | ----------------------------------------------------------- 9 | ----------------------------------------------------- 10 | -- Examining SQL Server with Code 11 | 12 | -- sp_help 13 | USE OBXKites; 14 | sp_help price; 15 | 16 | -- Global Variables 17 | Select @@Connections; 18 | Select @@CPU_Busy; 19 | Select @@Cursor_Rows; 20 | Select @@DateFirst; 21 | Select @@DBTS; 22 | Select @@Error; 23 | Select @@Fetch_Status; 24 | Select @@Identity; 25 | Select @@Idle; 26 | Select @@IO_Busy; 27 | Select @@LangID; 28 | Select @@Language; 29 | Select @@Lock_TimeOut; 30 | Select @@Max_Connections; 31 | Select @@Max_Precision; 32 | Select @@Nestlevel; 33 | Select @@Options; 34 | Select @@Pack_Received; 35 | Select @@Pack_Sent; 36 | Select @@Packet_Errors; 37 | Select @@ProcID; 38 | Select @@RemServer; 39 | Select @@RowCount; 40 | Select @@ServerName; 41 | Select @@ServiceName; 42 | Select @@SPID; 43 | Select @@TextSize; 44 | Select @@TimeTicks; 45 | Select @@Total_Errors; 46 | Select @@Total_Read; 47 | Select @@Total_Write; 48 | Select @@TranCount; 49 | Select @@Version; 50 | 51 | --------------------------------------------------- 52 | -- Using Temp Tables 53 | 54 | CREATE TABLE #ProductTemp ( 55 | ProductID INT PRIMARY KEY 56 | ); 57 | 58 | INSERT INTO #ProductTemp VALUES ( 1); 59 | 60 | SELECT * 61 | FROM #ProductTemp 62 | 63 | SELECT Name 64 | FROM TempDB.dbo.SysObjects 65 | WHERE Name Like '#Pro%' 66 | 67 | -- Global Temp Table 68 | IF NOT EXISTS( 69 | SELECT * FROM Tempdb.dbo.Sysobjects 70 | WHERE Name = '##TempWork') 71 | CREATE TABLE ##TempWork( 72 | PK INT, 73 | Col1 INT 74 | ); 75 | 76 | -- Table Variable 77 | DECLARE @WorkTable TABLE ( 78 | PK INT PRIMARY KEY, 79 | Col1 INT NOT NULL); 80 | 81 | INSERT INTO @WorkTable (PK, Col1) 82 | VALUES ( 1, 101); 83 | 84 | SELECT PK, Col1 85 | FROM @WorkTable; -------------------------------------------------------------------------------- /Lessons/LESSON_045.SQL: -------------------------------------------------------------------------------- 1 | ----------------------------------------------------------- 2 | -- SQL Server 2017 3 | -- 4 | -- Developing Solutions 5 | -- Lesson 45 - T-SQL and Stored Procedures 6 | -- 7 | -- Ahmed Mohamady 8 | ----------------------------------------------------------- 9 | ---------------------------------------------------------------- 10 | -- Developing Dynamic SQL 11 | 12 | -- Simple EXEC 13 | USE Family; 14 | EXEC ('Select LastName from Person Where PersonID = 12'); 15 | 16 | -- sp_executeSQL 17 | EXEC sp_executeSQL 18 | N'Select LastName from Person Where PersonID = @PersonSelect', 19 | N'@PersonSelect INT', 20 | @PersonSelect = 12; 21 | 22 | 23 | -- Developing Dynamic SQL Code 24 | USE OBXKites; 25 | 26 | DECLARE 27 | @SQL NVARCHAR(1024), 28 | @SQLWhere NVARCHAR(1024), 29 | @NeedsAnd BIT, 30 | 31 | -- User Parameters 32 | @ProductName VARCHAR(50), 33 | @ProductCode VARCHAR(10), 34 | @ProductCategory VARCHAR(50); 35 | 36 | -- Initilize Variables 37 | SET @NeedsAnd = 0; 38 | SET @SQLWhere = ''; 39 | 40 | -- Simulate User's Requirements 41 | SET @ProductName = NULL; 42 | SET @ProductCode = 1001; 43 | SET @ProductCategory = NULL; 44 | 45 | -- Assembling Dynamic SQL 46 | 47 | -- Set up initial SQL Select 48 | IF @ProductCategory IS NULL 49 | SET @SQL = 'Select ProductName from Product'; 50 | ELSE 51 | SET @SQL = 'Select ProductName from Product 52 | Join ProductCategory 53 | on Product.ProductCategoryID 54 | = ProductCategory.ProductCategoryID'; 55 | 56 | -- Build the Dynamic Where Clause 57 | IF @ProductName IS NOT NULL 58 | BEGIN; 59 | SET @SQLWhere = 'ProductName = ' + @ProductName; 60 | SET @NeedsAnd = 1; 61 | END; 62 | 63 | IF @ProductCode IS NOT NULL 64 | BEGIN; 65 | IF @NeedsAnd = 1 66 | SET @SQLWhere = @SQLWhere + ' and '; 67 | SET @SQLWhere = 'Code = ' + @ProductCode; 68 | SET @NeedsAnd = 1; 69 | END; 70 | 71 | IF @ProductCategory IS NOT NULL 72 | BEGIN; 73 | IF @NeedsAnd = 1 74 | SET @SQLWhere = @SQLWhere + ' and '; 75 | SET @SQLWhere = 'ProductCategory = ' + @ProductCategory ; 76 | SET @NeedsAnd = 1; 77 | END; 78 | 79 | -- Assemble the select and the where portions of the dynamic SQL 80 | IF @NeedsAnd = 1 81 | SET @SQL = @SQL + ' where ' + @SQLWhere; 82 | 83 | Print @SQL; 84 | 85 | EXEC sp_executeSQL @SQL 86 | WITH RECOMPILE; -------------------------------------------------------------------------------- /Lessons/LESSON_046.SQL: -------------------------------------------------------------------------------- 1 | ----------------------------------------------------------- 2 | -- SQL Server 2017 3 | -- 4 | -- Developing Solutions 5 | -- Lesson 46 - T-SQL and Stored Procedures 6 | -- 7 | -- Ahmed Mohamady 8 | ----------------------------------------------------------- 9 | --------------------------------------------- 10 | -- Introducing Stored Procedures 11 | 12 | -- Create, Alter, Drop 13 | USE OBXKites; 14 | go 15 | 16 | CREATE PROCEDURE CategoryList 17 | AS 18 | SELECT ProductCategoryName, ProductCategoryDescription 19 | FROM dbo.ProductCategory; 20 | RETURN; 21 | go 22 | 23 | -- Executing the Sproc & Returning a Result Set 24 | EXEC CategoryList; 25 | 26 | -- Calling Remote Stored Procedures 27 | EXEC [HPPRESENT\SECOND].OBXKites.dbo.pProductCategory_AddNew 'Food', 'Eat-ables' 28 | 29 | -- Compiling Stored Procedures 30 | CREATE PROCEDURE CategoryList 31 | WITH RECOMPILE 32 | AS 33 | SELECT ProductCategoryName, ProductCategoryDescription 34 | FROM dbo.ProductCategory; 35 | RETURN; 36 | go 37 | 38 | EXEC sp_recompile CategoryList; -------------------------------------------------------------------------------- /Lessons/LESSON_047.SQL: -------------------------------------------------------------------------------- 1 | ----------------------------------------------------------- 2 | -- SQL Server 2017 3 | -- 4 | -- Developing Solutions 5 | -- Lesson 47 - T-SQL and Stored Procedures 6 | -- 7 | -- Ahmed Mohamady 8 | ----------------------------------------------------------- 9 | ---------------------------------------------------- 10 | -- Passing Parameters 11 | 12 | -- Input Parameters 13 | USE OBXKites; 14 | 15 | go 16 | CREATE PROCEDURE CategoryGet 17 | (@CategoryName NVARCHAR(35)) 18 | AS 19 | SELECT ProductCategoryName, ProductCategoryDescription 20 | FROM dbo.ProductCategory 21 | WHERE ProductCategoryName = @CategoryName; 22 | go 23 | 24 | EXEC CategoryGet @CategoryName='Kite'; 25 | 26 | 27 | -- Parameter Defaults 28 | CREATE PROCEDURE pProductCategory_Fetch2( 29 | @Search NVARCHAR(50) = NULL 30 | ) 31 | -- If @Search = null then return all ProductCategories 32 | -- If @Search is value then try to find by Name 33 | AS 34 | SET NOCOUNT ON; 35 | SELECT ProductCategoryName, ProductCategoryDescription 36 | FROM dbo.ProductCategory 37 | WHERE ProductCategoryName = @Search 38 | OR @Search IS NULL; 39 | IF @@RowCount = 0 40 | RAISERROR('Product Category ''%s'' Not Found.',14,1,@Search); 41 | go 42 | 43 | EXEC pProductCategory_Fetch2 'OBX'; 44 | 45 | EXEC pProductCategory_Fetch2; -------------------------------------------------------------------------------- /Lessons/LESSON_048.SQL: -------------------------------------------------------------------------------- 1 | ----------------------------------------------------------- 2 | -- SQL Server 2017 3 | -- 4 | -- Developing Solutions 5 | -- Lesson 48 - T-SQL and Stored Procedures 6 | -- 7 | -- Ahmed Mohamady 8 | ----------------------------------------------------------- 9 | -------------------------------------------- 10 | -- Returning Parameters 11 | 12 | -- Output Parameters 13 | USE OBXKites; 14 | go 15 | CREATE PROC GetProductName ( 16 | @ProductCode CHAR(10), 17 | @ProductName VARCHAR(25) OUTPUT ) 18 | AS 19 | SELECT @ProductName = ProductName 20 | FROM dbo.Product 21 | WHERE Code = @ProductCode; 22 | go 23 | 24 | -- 25 | USE OBXKITES; 26 | DECLARE @ProdName VARCHAR(25); 27 | EXEC GetProductName '1001', @ProdName OUTPUT; 28 | PRINT @ProdName; 29 | 30 | -- Using the Return Command 31 | CREATE PROC IsItOK ( 32 | @OK VARCHAR(10) ) 33 | AS 34 | IF @OK = 'OK' 35 | RETURN 0 36 | ELSE 37 | RETURN -100; 38 | go 39 | 40 | 41 | DECLARE @ReturnCode INT; 42 | EXEC @ReturnCode = IsITOK 'OK'; 43 | PRINT @ReturnCode; 44 | EXEC @ReturnCode = IsItOK 'NotOK'; 45 | PRINT @ReturnCode; -------------------------------------------------------------------------------- /Lessons/LESSON_049.SQL: -------------------------------------------------------------------------------- 1 | ----------------------------------------------------------- 2 | -- SQL Server 2017 3 | -- 4 | -- Developing Solutions 5 | -- Lesson 49 - T-SQL and Stored Procedures 6 | -- 7 | -- Ahmed Mohamady 8 | ----------------------------------------------------------- 9 | ---------------------------------------------------------- 10 | -- Iterating through rows 11 | 12 | 13 | USE Family 14 | DECLARE @Name VARCHAR(100) 15 | 16 | -- Fast Forward Cursor / Function 17 | -- 1 18 | DECLARE cDetail CURSOR FAST_FORWARD READ_ONLY 19 | FOR SELECT FirstName + ' ' + LastName 20 | FROM Person 21 | ORDER BY DateofBirth 22 | -- 2 23 | OPEN cDetail 24 | -- 3 25 | FETCH cDetail INTO @Name -- prime the cursor 26 | PRINT @Name 27 | 28 | WHILE @@Fetch_Status = 0 29 | BEGIN 30 | PRINT @Name 31 | 32 | -- 3 33 | FETCH cDetail INTO @Name -- fetch next 34 | END 35 | 36 | -- 4 37 | CLOSE cDetail 38 | 39 | -- 5 40 | DEALLOCATE cDetail -------------------------------------------------------------------------------- /Lessons/LESSON_051.SQL: -------------------------------------------------------------------------------- 1 | ----------------------------------------------------------- 2 | -- SQL Server 2017 3 | -- 4 | -- Developing Solutions 5 | -- Lesson 51 - T-SQL Handling Errors 6 | -- 7 | -- Ahmed Mohamady 8 | ----------------------------------------------------------- 9 | ---------------------------------------------------------- 10 | -- Handling Errors 11 | 12 | -- Try...Catch 13 | BEGIN TRY; 14 | SET NOCOUNT ON; 15 | SELECT 'Try One'; 16 | RAISERROR('Simulated Error', 16, 1); 17 | Select 'Try Two'; 18 | END TRY 19 | BEGIN CATCH; 20 | SELECT 'Catch Block'; 21 | END CATCH ; 22 | SELECT 'Try Three'; 23 | 24 | 25 | BEGIN TRY; 26 | SET NOCOUNT ON; 27 | SELECT 'Try One'; 28 | RAISERROR('Simulated Error', 16, 1) ; 29 | Select 'Try Two'; 30 | END TRY 31 | 32 | BEGIN CATCH 33 | SELECT 34 | ERROR_MESSAGE() AS [Message], 35 | ERROR_PROCEDURE() AS [Procedure], 36 | ERROR_LINE() AS Line, 37 | ERROR_NUMBER() AS Number, 38 | ERROR_SEVERITY() AS Severity, 39 | ERROR_STATE() AS State; 40 | END CATCH; 41 | SELECT 'Try Three'; 42 | 43 | -- Without a Catch Block the Functions Return a Null 44 | SELECT 45 | ERROR_MESSAGE() AS [Message], 46 | ERROR_PROCEDURE() AS [Procedure], 47 | ERROR_LINE() AS Line, 48 | ERROR_NUMBER() AS Number, 49 | ERROR_SEVERITY() AS Severity, 50 | ERROR_STATE() AS State; 51 | 52 | -- Legacy @@Error Global Variable 53 | USE Family; 54 | UPDATE Person 55 | SET PersonID = 1 56 | Where PersonID = 2; 57 | Print @@Error; 58 | Print @@Error; 59 | 60 | -- Saving @@Error to a Local Variable 61 | USE Family; 62 | DECLARE @err INT; 63 | 64 | UPDATE Person 65 | SET PersonID = 1 66 | Where PersonID = 2; 67 | SET @err = @@Error; 68 | 69 | IF @err <> 0 70 | Begin; 71 | -- error handling code 72 | Print @err; 73 | End; 74 | 75 | -- Legacy @@RowCount Global Variable 76 | USE FAMILY; 77 | UPDATE Person 78 | SET LastName = 'Johnson' 79 | WHERE PersonID = 100; 80 | 81 | IF @@RowCount = 0 82 | Begin; 83 | -- error handling code 84 | Print 'no rows affected'; 85 | End; 86 | 87 | -- Raiserror 88 | 89 | 90 | -- The Complete Raiserror Form 91 | RAISERROR('Unable to update Customer', 14, 1); 92 | 93 | -- Error Severity 94 | RAISERROR('Print', 10,1); 95 | RAISERROR('Info', 14,1); 96 | RAISERROR('Warning', 15,1); 97 | RAISERROR('Critical', 16,1); 98 | 99 | -- Adding Variable Parameters to Message 100 | RAISERROR ('Unable to update %s.', 14, 1, 'Customer'); 101 | 102 | -------------------------------------------------------------------------------- /Lessons/LESSON_052.SQL: -------------------------------------------------------------------------------- 1 | ----------------------------------------------------------- 2 | -- SQL Server 2019 3 | -- 4 | -- Developing Solutions 5 | -- Lesson 52- T-SQL Programming - Triggers and Audit Trail 6 | -- 7 | -- Ahmed Mohamady 8 | ----------------------------------------------------------- 9 | ----------------------------------------------------------- 10 | -- Introducing After Triggers 11 | 12 | USE FAMILY 13 | go 14 | CREATE TRIGGER TriggerOne ON Person 15 | AFTER Insert -- old syntax FOR 16 | AS 17 | PRINT 'In the After Trigger' 18 | go 19 | 20 | INSERT Person(PersonID, LastName, FirstName, Gender) 21 | VALUES (50, 'Flanigan', 'Brandie','F') -------------------------------------------------------------------------------- /Lessons/LESSON_053.SQL: -------------------------------------------------------------------------------- 1 | ----------------------------------------------------------- 2 | -- SQL Server 2019 3 | -- 4 | -- Developing Solutions 5 | -- Lesson 53- T-SQL Programming - Triggers and Audit Trail 6 | -- 7 | -- Ahmed Mohamady 8 | ----------------------------------------------------------- 9 | ----------------------------------------------------------------------- 10 | -- Using "Instead of" Triggers 11 | 12 | USE FAMILY 13 | 14 | CREATE TRIGGER TriggerTwo ON Person 15 | INSTEAD OF Insert 16 | AS 17 | PRINT 'In the Instead-of Trigger' 18 | go 19 | 20 | INSERT Person(PersonID, LastName, FirstName, Gender) 21 | VALUES (99, 'McDoogle', 'John','M') 22 | 23 | SELECT * 24 | FROM Person 25 | WHERE PersonID = 99 26 | 27 | DROP TRIGGER TriggerTwo 28 | 29 | /* 30 | Transaction Flow 31 | 1 - Identity Insert Check 32 | 2 - Nullability Constraint 33 | 3 - Data Type Check 34 | 4 - Instead of Trigger 35 | 5 - Primary Key Constraint 36 | 6 - Check Constraints 37 | 7 - Foreign Key Constraint 38 | 8 - DML execution and update to Transaction Log 39 | 9 - After Trigger 40 | 10 - Commit Transaction 41 | */ -------------------------------------------------------------------------------- /Lessons/LESSON_054.SQL: -------------------------------------------------------------------------------- 1 | ----------------------------------------------------------- 2 | -- SQL Server 2019 3 | -- 4 | -- Developing Solutions 5 | -- Lesson 54- T-SQL Programming - Triggers and Audit Trail 6 | -- 7 | -- Ahmed Mohamady 8 | ----------------------------------------------------------- 9 | -------------------------------------------------------- 10 | -- Disabling Triggers 11 | 12 | ALTER TABLE Person 13 | DISABLE TRIGGER TriggerOne 14 | 15 | SELECT OBJECTPROPERTY(OBJECT_ID('TriggerOne'),'ExecIsTriggerDisabled') 16 | 17 | 18 | ALTER TABLE Person 19 | ENABLE TRIGGER TriggerOne 20 | 21 | SELECT OBJECTPROPERTY(OBJECT_ID('TriggerOne'),'ExecIsTriggerDisabled') 22 | 23 | 24 | -- Viewing Trigger Status 25 | SELECT SubString(S2.Name,1,30) as [Table], 26 | SubString(S.Name, 1,30) as [Trigger], 27 | CASE (SELECT -- Correlated subquery 28 | OBJECTPROPERTY(OBJECT_ID(S.Name), 29 | 'ExecIsTriggerDisabled')) 30 | WHEN 0 THEN 'Enabled' 31 | WHEN 1 THEN 'Disabled' 32 | END AS Status 33 | FROM Sysobjects S 34 | JOIN Sysobjects S2 35 | ON S.parent_obj = S2.ID 36 | WHERE S.Type = 'TR' 37 | ORDER BY [Table], [Trigger] 38 | 39 | 40 | ------------------------------------------------------- 41 | -- Using the Update() function 42 | 43 | ALTER TRIGGER TriggerOne ON Person 44 | AFTER Insert, Update 45 | AS 46 | IF Update(LastName) 47 | PRINT 'You modified the LastName column' 48 | ELSE 49 | PRINT 'The LastName column is untouched.' 50 | 51 | 52 | UPDATE Person 53 | SET LastName = 'Johnson' 54 | WHERE PersonID = 25 55 | 56 | UPDATE Person 57 | SET FirstName = 'Joe' 58 | WHERE PersonID = 25 59 | 60 | 61 | ----------------------------------------------- 62 | -- Selecting Transaction Data 63 | 64 | USE Family 65 | 66 | ALTER TRIGGER TriggerOne ON Person 67 | AFTER Insert, Update 68 | AS 69 | SET NoCount ON 70 | IF Update(LastName) 71 | SELECT 'You modified the LastName column to ' + Inserted.LastName 72 | FROM Inserted 73 | 74 | 75 | UPDATE Person 76 | SET LastName = 'Johnson' 77 | WHERE PersonID = 32 78 | 79 | ALTER TRIGGER TriggerOne ON Person 80 | AFTER Insert, Update 81 | AS 82 | SELECT CAST(D.PersonID as VARCHAR(4)) + ': ' + D.LastName + ' changed to ' + I.LastName 83 | FROM Inserted I 84 | JOIN Deleted D 85 | ON I.PersonID = D.PersonID 86 | 87 | UPDATE Person 88 | SET LastName = 'Carter' 89 | WHERE LastName = 'Johnson' 90 | -------------------------------------------------------------------------------- /Lessons/LESSON_055.SQL: -------------------------------------------------------------------------------- 1 | ----------------------------------------------------------- 2 | -- SQL Server 2020 3 | -- 4 | -- Developing Solutions 5 | -- Lesson 55- T-SQL Programming - Triggers and Audit Trail 6 | -- 7 | -- Ahmed Mohamady 8 | ----------------------------------------------------------- 9 | 10 | -- Nested - Server wide setting 11 | EXEC sp_configure 'Nested Triggers', 1 12 | Reconfigure 13 | 14 | 15 | 16 | -- Recursive Trigger - Database wide setting 17 | USE OBXKites 18 | 19 | ALTER DATABASE OBXKites SET RECURSIVE_TRIGGERS ON 20 | 21 | ALTER TABLE Product 22 | ADD Created DATETIME NOT NULL DEFAULT GetDate() 23 | ALTER TABLE Product 24 | ADD Modified DATETIME NOT NULL DEFAULT GetDate() 25 | 26 | 27 | -- assumes created and modified date columns have been added to the Product table. 28 | CREATE TRIGGER Products_ModifiedDate ON dbo.Product 29 | AFTER UPDATE 30 | AS 31 | SET NoCount ON 32 | -- Check nest level 33 | PRINT Trigger_NestLevel() -- for demo purposes, remove from production code 34 | If Trigger_NestLevel() > 1 35 | RETURN 36 | -- block manual update of created/modified columns 37 | IF (UPDATE(Created) or UPDATE(Modified)) 38 | AND Trigger_NestLevel() = 1 39 | BEGIN 40 | RAISERROR('Update failed.', 16, 1) 41 | ROLLBACK 42 | RETURN 43 | END 44 | -- Update the Modified date 45 | UPDATE Product 46 | SET modified = getdate() 47 | FROM Product 48 | JOIN Inserted 49 | ON Product.ProductID = Inserted.ProductID 50 | -- end of trigger 51 | go 52 | 53 | 54 | 55 | 56 | UPDATE PRODUCT 57 | SET ProductName = 'Modifed Trigger' 58 | WHERE Code = '1002' 59 | 60 | SELECT Code, ProductName, Created, Modified 61 | FROM Product 62 | WHERE Code = '1002' 63 | -------------------------------------------------------------------------------- /Lessons/LESSON_056.SQL: -------------------------------------------------------------------------------- 1 | ----------------------------------------------------------- 2 | -- SQL Server 2020 3 | -- 4 | -- Developing Solutions 5 | -- Lesson 56- T-SQL Programming - Triggers and Audit Trail 6 | -- 7 | -- Ahmed Mohamady 8 | ----------------------------------------------------------- 9 | -------------------------------------------------------- 10 | -- Enforcing Complex RI 11 | 12 | -- Complex Business Rules Validation 13 | -- Custom RI 14 | 15 | -- ensure the guide's qual date is good and the revoke date is null 16 | -- for the given guideID and TourID 17 | 18 | USE CHA2 19 | go 20 | CREATE TRIGGER LeadQualied ON Event_mm_Guide 21 | AFTER INSERT, UPDATE 22 | AS 23 | SET NoCount ON 24 | IF EXISTS( 25 | SELECT * 26 | FROM Inserted 27 | JOIN dbo.Event 28 | ON Inserted.EventID = Event.EventID 29 | LEFT JOIN dbo.Tour_mm_Guide 30 | ON Tour_mm_Guide.TourID = Event.TourID 31 | AND Inserted.GuideID = Tour_mm_Guide.GuideID 32 | WHERE 33 | Inserted.IsLead = 1 34 | AND 35 | (QualDate > Event.DateBegin 36 | OR 37 | RevokeDate IS NOT NULL 38 | OR 39 | QualDate IS NULL ) 40 | ) 41 | BEGIN 42 | RAISERROR('Lead Guide is not Qualified.',16,1) 43 | ROLLBACK TRANSACTION 44 | END 45 | go 46 | 47 | 48 | -- test 49 | 50 | INSERT Event_mm_Guide (EventID, GuideID, IsLead) 51 | VALUES (10, 1, 1) 52 | 53 | INSERT Event_mm_Guide (EventID, GuideID, IsLead) 54 | VALUES (10, 2, 1) -------------------------------------------------------------------------------- /Lessons/LESSON_057.SQL: -------------------------------------------------------------------------------- 1 | ----------------------------------------------------------- 2 | -- SQL Server 2020 3 | -- 4 | -- Developing Solutions 5 | -- Lesson 57- T-SQL Programming - Triggers and Audit Trail 6 | -- 7 | -- Ahmed Mohamady 8 | ----------------------------------------------------------- 9 | ------------------------------------------------------- 10 | -- Auditing Data Changes 11 | 12 | USE OBXKites 13 | 14 | CREATE TABLE dbo.Audit ( 15 | AuditID UNIQUEIDENTIFIER RowGUIDCol NOT NULL 16 | CONSTRAINT DF_Audit_AuditID DEFAULT (NEWID()) 17 | CONSTRAINT PK_Audit PRIMARY KEY NONCLUSTERED (AuditID), 18 | AuditDate DATETIME NOT NULL, 19 | SysUser VARCHAR(50) NOT NULL, 20 | Application VARCHAR(50) NOT NULL, 21 | TableName VARCHAR(50)NOT NULL, 22 | Operation CHAR(1) NOT NULL, 23 | PrimaryKey VARCHAR(50) NOT NULL, 24 | RowDescription VARCHAR(50) NULL, 25 | SecondaryRow VARCHAR(50) NULL, 26 | [Column] VARCHAR(50) NOT NULL, 27 | OldValue VARCHAR(50) NULL, 28 | NewValue VARCHAR(50) NULL 29 | ) 30 | 31 | -------------------------------------------------------------- 32 | -- Fixed Audit Trail Trigger 33 | 34 | Use OBXKites 35 | 36 | Go 37 | 38 | CREATE TRIGGER Product_Audit 39 | ON dbo.Product 40 | AFTER Insert, Update 41 | NOT FOR REPLICATION 42 | AS 43 | 44 | DECLARE @Operation CHAR(1) 45 | 46 | IF EXISTS(SELECT * FROM Deleted) 47 | SET @Operation = 'U' 48 | ELSE 49 | SET @Operation = 'I' 50 | 51 | IF UPDATE(ProductCategoryID) 52 | INSERT dbo.Audit 53 | (AuditDate, SysUser, Application, TableName, Operation, 54 | PrimaryKey, RowDescription, SecondaryRow, [Column], 55 | OldValue, NewValue) 56 | SELECT GetDate(), suser_sname(), APP_NAME(), 'Product', @Operation, 57 | Inserted.ProductID, Inserted.Code, NULL, 'ProductCategoryID', 58 | OPC.ProductCategoryName, NPC.ProductCategoryName 59 | FROM Inserted 60 | LEFT OUTER JOIN Deleted 61 | ON Inserted.ProductID = Deleted.ProductID 62 | AND Inserted.ProductCategoryID 63 | <> Deleted.ProductCategoryID 64 | -- fetch ProductCategory Names 65 | LEFT OUTER JOIN dbo.ProductCategory OPC 66 | ON Deleted.ProductCategoryID = OPC.ProductCategoryID 67 | JOIN dbo.ProductCategory NPC 68 | ON Inserted.ProductCategoryID = NPC.ProductCategoryID 69 | 70 | IF UPDATE(Code) 71 | INSERT dbo.Audit 72 | (AuditDate, SysUser, Application, TableName, Operation, 73 | PrimaryKey, RowDescription, SecondaryRow, [Column], 74 | OldValue, NewValue) 75 | SELECT GetDate(), suser_sname(), APP_NAME(), 'Product', @Operation, 76 | Inserted.ProductID, Inserted.Code, NULL, 'Code', 77 | Deleted.Code, Inserted.Code 78 | FROM Inserted 79 | LEFT OUTER JOIN Deleted 80 | ON Inserted.ProductID = Deleted.ProductID 81 | AND Inserted.Code <> Deleted.Code 82 | 83 | IF UPDATE(ProductName) 84 | INSERT dbo.Audit 85 | (AuditDate, SysUser, Application, TableName, Operation, 86 | PrimaryKey, RowDescription, SecondaryRow, [Column], 87 | OldValue, NewValue) 88 | SELECT GetDate(), suser_sname(), APP_NAME(), 'Product', @Operation, 89 | Inserted.ProductID, Inserted.Code, NULL, 'Name', 90 | Deleted.ProductName, Inserted.ProductName 91 | FROM Inserted 92 | LEFT OUTER JOIN Deleted 93 | ON Inserted.ProductID = Deleted.ProductID 94 | AND Inserted.ProductName <> Deleted.ProductName 95 | 96 | IF UPDATE(ProductDescription) 97 | INSERT dbo.Audit 98 | (AuditDate, SysUser, Application, TableName, Operation, 99 | PrimaryKey, RowDescription, SecondaryRow, [Column], 100 | OldValue, NewValue) 101 | SELECT GetDate(), suser_sname(), APP_NAME(), 'Product', @Operation, 102 | Inserted.ProductID, Inserted.Code, NULL, 'ProductDescription', 103 | Deleted.ProductDescription, Inserted.ProductDescription 104 | FROM Inserted 105 | LEFT OUTER JOIN Deleted 106 | ON Inserted.ProductID = Deleted.ProductID 107 | AND Inserted.ProductDescription <> Deleted.ProductDescription 108 | 109 | IF UPDATE(ActiveDate) 110 | INSERT dbo.Audit 111 | (AuditDate, SysUser, Application, TableName, Operation, 112 | PrimaryKey, RowDescription, SecondaryRow, [Column], 113 | OldValue, NewValue) 114 | SELECT GetDate(), suser_sname(), APP_NAME(), 'Product', @Operation, 115 | Inserted.ProductID, Inserted.Code, NULL, 'ActiveDate', 116 | Deleted.ActiveDate, Inserted.ActiveDate 117 | FROM Inserted 118 | LEFT OUTER JOIN Deleted 119 | ON Inserted.ProductID = Deleted.ProductID 120 | AND Inserted.ActiveDate != Deleted.ActiveDate 121 | 122 | IF UPDATE(DiscontinueDate) 123 | INSERT dbo.Audit 124 | (AuditDate, SysUser, Application, TableName, Operation, 125 | PrimaryKey, RowDescription, SecondaryRow, [Column], 126 | OldValue, NewValue) 127 | SELECT GetDate(), suser_sname(), APP_NAME(), 'Product', @Operation, 128 | Inserted.ProductID, Inserted.Code, NULL, 'DiscontinueDate', 129 | Deleted.DiscontinueDate, Inserted.DiscontinueDate 130 | FROM Inserted 131 | LEFT OUTER JOIN Deleted 132 | ON Inserted.ProductID = Deleted.ProductID 133 | AND Inserted.DiscontinueDate != Deleted.DiscontinueDate 134 | 135 | go 136 | 137 | -- Test the Fixed Audit Trail 138 | 139 | EXEC pProduct_AddNew 'Kite', 200, 'The MonstaKite', 'Man what a big Kite!' 140 | 141 | SELECT TableName, RowDescription, [Column], NewValue 142 | FROM Audit 143 | 144 | SELECT * 145 | FROM Audit 146 | 147 | UPDATE dbo.Product 148 | SET ProductDescription = 'Biggie Sized' 149 | WHERE Code = 200 150 | 151 | SELECT AuditDate, OldValue, NewValue 152 | FROM dbo.Audit 153 | WHERE TableName = 'Product' 154 | AND RowDescription = '200' 155 | AND [Column] = 'ProductDescription' 156 | 157 | --Rolling back an Audit Trail change 158 | 159 | CREATE PROCEDURE pAudit_RollBack ( 160 | @AuditID UNIQUEIDENTIFIER) 161 | AS 162 | SET NoCount ON 163 | 164 | DECLARE 165 | @SQLString NVARCHAR(4000), 166 | @TableName NVARCHAR(50), 167 | @PrimaryKey NVARCHAR(50), 168 | @Column NVARCHAR(50), 169 | @NewValue NVARCHAR(50) 170 | 171 | SELECT 172 | @TableName = TableName, 173 | @PrimaryKey = PrimaryKey, 174 | @Column = [Column], 175 | @NewValue = OldValue 176 | FROM dbo.Audit 177 | WHERE AuditID = @AuditID 178 | 179 | SET @SQLString = 180 | 'UPDATE ' + @TableName 181 | + ' SET ' + @Column + ' = ''' + @NewValue +'''' 182 | + ' WHERE ' + @TableName + 'ID = ''' + @PrimaryKey + '''' 183 | 184 | EXEC sp_executeSQL @SQLString 185 | go 186 | 187 | --Test RollBack 188 | 189 | DECLARE @AuditRollBack UNIQUEIDENTIFIER 190 | 191 | SELECT @AuditRollBack = AuditID 192 | FROM dbo.Audit 193 | WHERE TableName = 'Product' 194 | AND RowDescription = '200' 195 | AND OldValue = 'Man what a big Kite!' 196 | 197 | EXEC pAudit_RollBack @AuditRollBack 198 | 199 | SELECT ProductDescription 200 | FROM dbo.Product 201 | WHERE Code = 200 -------------------------------------------------------------------------------- /Northwind.bak: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/alMohamady/SampleDatabases/34b053ebf7b165cc5523e9ec890af036bb1ad998/Northwind.bak -------------------------------------------------------------------------------- /OBXKites/OBXKites_Create.sql: -------------------------------------------------------------------------------- 1 | 2 | ----------------------------------------------------------- 3 | -- OBX Kites sample database - CREATE Database, Tables, and Procs 4 | 5 | -- this script will drop an existing OBXKites database 6 | -- and create a fresh new installation 7 | 8 | -- related scripts: 9 | -- OBXKites_Populate 10 | 11 | -- T-SQL KEYWORDS go 12 | -- DatabaseNames 13 | 14 | ----------------------------------------------------------- 15 | ----------------------------------------------------------- 16 | -- Drop and Create Database 17 | 18 | 19 | USE master 20 | GO 21 | IF EXISTS (SELECT * FROM SysDatabases WHERE NAME='OBXKites') 22 | DROP DATABASE OBXKites 23 | go 24 | 25 | -- This creates 1 database that uses 2 filegroups 26 | CREATE DATABASE OBXKites 27 | 28 | 29 | -- set to Full Log 30 | 31 | go 32 | 33 | SET QUOTED_IDENTIFIER ON 34 | go 35 | USE OBXKites 36 | go 37 | 38 | ----------------------------------------------------------- 39 | ----------------------------------------------------------- 40 | -- Create Tables, in order from primary to secondary 41 | 42 | CREATE TABLE dbo.OrderPriority ( 43 | OrderPriorityID UNIQUEIDENTIFIER NOT NULL ROWGUIDCOL DEFAULT (NEWID()) PRIMARY KEY NONCLUSTERED, 44 | OrderPriorityName NVARCHAR (15) NOT NULL, 45 | OrderPriorityCode NVARCHAR (15) NOT NULL, 46 | Priority INT NOT NULL 47 | ) 48 | 49 | go 50 | 51 | CREATE TABLE dbo.ProductCategory ( 52 | ProductCategoryID UNIQUEIDENTIFIER NOT NULL ROWGUIDCOL DEFAULT (NEWID()) PRIMARY KEY NONCLUSTERED, 53 | ProductCategoryName NVARCHAR(50) NOT NULL, 54 | ProductCategoryDescription NVARCHAR(100) NULL 55 | ) 56 | ON [Primary] 57 | go 58 | CREATE UNIQUE CLUSTERED INDEX ProductCategoryName 59 | ON ProductCategory (ProductCategoryName) 60 | ON [Primary] 61 | go 62 | CREATE TABLE dbo.Product ( 63 | ProductID UNIQUEIDENTIFIER NOT NULL ROWGUIDCOL DEFAULT (NEWID()) PRIMARY KEY NONCLUSTERED, 64 | RowVersion Rowversion NOT NULL, 65 | ProductCategoryID UNIQUEIDENTIFIER NOT NULL FOREIGN KEY REFERENCES dbo.ProductCategory, 66 | Code CHAR(15) NOT NULL, 67 | ProductName NVARCHAR(50) NOT NULL, 68 | ProductDescription NVARCHAR(100) NULL, 69 | ActiveDate DATETIME NOT NULL DEFAULT GETDATE(), 70 | DiscontinueDate DATETIME NULL 71 | ) 72 | go 73 | CREATE TABLE dbo.CustomerType ( 74 | CustomerTypeID UNIQUEIDENTIFIER NOT NULL ROWGUIDCOL DEFAULT (NEWID()) 75 | PRIMARY KEY NONCLUSTERED, 76 | CustomerTypeName NVARCHAR(50) NOT NULL, 77 | DiscountPercent NUMERIC (4,2) NOT NULL DEFAULT (0), 78 | [Default] BIT NOT NULL DEFAULT 0 79 | ) 80 | go 81 | 82 | CREATE TABLE dbo.Contact ( 83 | ContactID UNIQUEIDENTIFIER NOT NULL ROWGUIDCOL DEFAULT (NEWID()) 84 | PRIMARY KEY NONCLUSTERED, 85 | ContactCode CHAR(15) NOT NULL, 86 | SoundexCode CHAR(4) NULL, 87 | LastName NVARCHAR(50) NOT NULL, 88 | FirstName NVARCHAR(50) NOT NULL, 89 | CompanyName NVARCHAR(50) NULL, 90 | CustomerTypeID UNIQUEIDENTIFIER NULL FOREIGN KEY REFERENCES dbo.CustomerType, 91 | CustomerSince CHAR(4) NULL, 92 | 93 | IsCustomer BIT NOT NULL DEFAULT (1), 94 | IsEmployee BIT NOT NULL DEFAULT (0), 95 | IsSupplier BIT NOT NULL DEFAULT (0), 96 | 97 | HomePhone NVARCHAR(50) NULL, 98 | HomeAddress1 NVARCHAR(50) NULL, 99 | HomeAddress2 NVARCHAR(50) NULL, 100 | HomeCity NVARCHAR(50) NULL, 101 | HomeRegion NVARCHAR(50) NULL, 102 | HomePostalCode NVARCHAR(50) NULL, 103 | HomeCountry NVARCHAR(50) NULL, 104 | OBXPhone NVARCHAR(50) NULL, 105 | OBXAddress1 NVARCHAR(50) NULL, 106 | OBXAddress2 NVARCHAR(50) NULL, 107 | OBXCity NVARCHAR(50) NULL, 108 | OBXRegion NVARCHAR(50) NULL, 109 | OBXPostalCode NVARCHAR(50) NULL, 110 | OBXCountry NVARCHAR(50) NULL 111 | ) 112 | go 113 | CREATE CLUSTERED INDEX IxContact 114 | ON dbo.Contact (SoundexCode) 115 | 116 | go 117 | CREATE TABLE dbo.Location ( 118 | LocationID UNIQUEIDENTIFIER NOT NULL ROWGUIDCOL DEFAULT (NEWID()) 119 | PRIMARY KEY NONCLUSTERED, 120 | LocationCode CHAR(5), 121 | LocationName NVARCHAR(50) NOT NULL, 122 | IsRetail BIT NOT NULL DEFAULT (0) 123 | ) 124 | go 125 | CREATE TABLE dbo.[Order] ( 126 | OrderID UNIQUEIDENTIFIER NOT NULL ROWGUIDCOL DEFAULT (NEWID()) PRIMARY KEY NONCLUSTERED, 127 | OrderNumber INT NOT NULL, 128 | ContactID UNIQUEIDENTIFIER NULL FOREIGN KEY REFERENCES dbo.Contact, 129 | OrderPriorityID UNIQUEIDENTIFIER NULL FOREIGN KEY REFERENCES dbo.OrderPriority, 130 | EmployeeID UNIQUEIDENTIFIER NULL FOREIGN KEY REFERENCES dbo.Contact, 131 | LocationID UNIQUEIDENTIFIER NULL FOREIGN KEY REFERENCES dbo.Location, 132 | OrderDate DATETIME NOT NULL DEFAULT (GETDATE()), 133 | Closed BIT NOT NULL DEFAULT (0) -- set to true when Closed 134 | ) 135 | ON [Primary] 136 | go 137 | 138 | CREATE TABLE dbo.OrderDetail ( 139 | OrderDetailID UNIQUEIDENTIFIER NOT NULL ROWGUIDCOL DEFAULT (NEWID()) PRIMARY KEY NONCLUSTERED, 140 | OrderID UNIQUEIDENTIFIER NOT NULL FOREIGN KEY REFERENCES dbo.[Order] ON DELETE CASCADE, 141 | ProductID UNIQUEIDENTIFIER NULL FOREIGN KEY REFERENCES dbo.Product, 142 | NonStockProduct NVARCHAR(256), 143 | Quantity NUMERIC(7,2) NOT NULL, 144 | UnitPrice MONEY NOT NULL, 145 | ExtendedPrice AS Quantity * UnitPrice, 146 | ShipRequestDate DATETIME, 147 | ShipDate DATETIME, 148 | ShipComment NVARCHAR(256) 149 | ) 150 | ON [Primary] 151 | go 152 | 153 | CREATE TABLE dbo.Price ( 154 | PriceID UNIQUEIDENTIFIER NOT NULL ROWGUIDCOL DEFAULT (NEWID()) PRIMARY KEY NONCLUSTERED, 155 | ProductID UNIQUEIDENTIFIER NOT NULL FOREIGN KEY REFERENCES dbo.Product, 156 | Price MONEY NOT NULL, 157 | EffectiveDate DATETIME NOT NULL 158 | ) 159 | go 160 | 161 | CREATE TABLE dbo.Inventory ( 162 | InventoryID UNIQUEIDENTIFIER NOT NULL ROWGUIDCOL DEFAULT (NEWID()) PRIMARY KEY NONCLUSTERED, 163 | InventoryCode CHAR(15) NOT NULL, 164 | LocationID UNIQUEIDENTIFIER NOT NULL FOREIGN KEY REFERENCES dbo.Location, 165 | ProductID UNIQUEIDENTIFIER NOT NULL FOREIGN KEY REFERENCES dbo.Product, 166 | QuantityOnHand INTEGER NOT NULL Default 0 167 | ) 168 | ON [Primary] 169 | go 170 | CREATE TABLE dbo.InventoryTransaction ( 171 | InventoryTransactionID UNIQUEIDENTIFIER NOT NULL ROWGUIDCOL DEFAULT (NEWID()) PRIMARY KEY NONCLUSTERED, 172 | Value NVARCHAR(50) NOT NULL, 173 | InventoryID UNIQUEIDENTIFIER NOT NULL FOREIGN KEY REFERENCES dbo.Inventory 174 | ) 175 | ON [Primary] 176 | go 177 | CREATE TABLE dbo.Supplier ( 178 | SupplierID UNIQUEIDENTIFIER NOT NULL ROWGUIDCOL DEFAULT (NEWID()) PRIMARY KEY NONCLUSTERED, 179 | ContactID UNIQUEIDENTIFIER NOT NULL FOREIGN KEY REFERENCES dbo.Contact, 180 | ProductID UNIQUEIDENTIFIER NOT NULL FOREIGN KEY REFERENCES dbo.Product 181 | ) 182 | go 183 | CREATE TABLE dbo.PO ( 184 | POID UNIQUEIDENTIFIER NOT NULL ROWGUIDCOL DEFAULT (NEWID()) PRIMARY KEY NONCLUSTERED, 185 | PONumber CHAR(15) NOT NULL, 186 | ContactID UNIQUEIDENTIFIER NOT NULL FOREIGN KEY REFERENCES dbo.Contact 187 | ) 188 | ON [Primary] 189 | go 190 | CREATE TABLE dbo.PODetail ( 191 | PODetailID UNIQUEIDENTIFIER NOT NULL ROWGUIDCOL DEFAULT (NEWID()) PRIMARY KEY NONCLUSTERED, 192 | POID UNIQUEIDENTIFIER NOT NULL FOREIGN KEY REFERENCES dbo.PO, 193 | ProductID UNIQUEIDENTIFIER NOT NULL FOREIGN KEY REFERENCES dbo.Product 194 | ) 195 | ON [Primary] 196 | go 197 | 198 | 199 | ----------------------------------------------------------------------- 200 | ----------------------------------------------------------------------- 201 | 202 | -- SPROCS 203 | USE OBXKites 204 | 205 | go 206 | 207 | ----------------------------------------------------------------- 208 | -- ProductCategory Sprocs 209 | ----------------------------------------------------------------- 210 | 211 | CREATE PROCEDURE pProductCategory_AddNew( 212 | @ProductCategoryName NVARCHAR(50), 213 | @ProductCategoryDescription NVARCHAR(100) = NULL 214 | ) 215 | AS 216 | SET NOCOUNT ON 217 | INSERT dbo.ProductCategory (ProductCategoryName, ProductCategoryDescription) 218 | VALUES (@ProductCategoryName, @ProductCategoryDescription) 219 | go 220 | 221 | ----------------------------------------------------------------- 222 | CREATE PROCEDURE pProductCategory_Fetch 223 | -- If @Search = null then return all ProductCategories 224 | -- If @Search is value then try to find by Name 225 | AS 226 | SET NOCOUNT ON 227 | SELECT ProductCategoryID, ProductCategoryName, ProductCategoryDescription 228 | FROM dbo.ProductCategory 229 | 230 | go 231 | 232 | 233 | ------------------------------------------------------------------ 234 | CREATE PROCEDURE pProductCategory_FetchID( 235 | @Search UNIQUEIDENTIFIER 236 | ) 237 | -- If @Search = null then return all ProductCategories 238 | -- If @Search is value then try to find by Name 239 | AS 240 | SET NOCOUNT ON 241 | IF EXISTS(SELECT * FROM dbo.ProductCategory WHERE ProductCategoryID = @Search) 242 | SELECT ProductCategoryID, ProductCategoryName, ProductCategoryDescription 243 | FROM dbo.ProductCategory 244 | WHERE ProductCategoryID = @Search 245 | ELSE 246 | RAISERROR('ProductID Not Found.',14,1) 247 | go 248 | 249 | ----------------------------------------------------------------- 250 | CREATE PROCEDURE pProductCategory_Delete( 251 | @ProductCategoryID UNIQUEIDENTIFIER 252 | ) 253 | AS 254 | SET NOCOUNT ON 255 | DELETE dbo.ProductCategory 256 | WHERE ProductCategoryID = @ProductCategoryID 257 | go 258 | 259 | 260 | ----------------------------------------------------------------- 261 | -- CustomerType Sprocs 262 | ----------------------------------------------------------------- 263 | 264 | CREATE PROCEDURE pCustomerType_AddNew( 265 | @Name NVARCHAR(50), 266 | @DiscountPercent NUMERIC (4,2) = 0, 267 | @Default BIT = 0 268 | ) 269 | AS 270 | SET NOCOUNT ON 271 | INSERT dbo.CustomerType (CustomerTypeName, DiscountPercent,[Default]) 272 | VALUES (@Name, @DiscountPercent, @Default) 273 | go 274 | 275 | -------------------------------------------------------------- 276 | CREATE PROCEDURE pCustomerType_Fetch( 277 | @Search NVARCHAR(50) = NULL 278 | ) 279 | AS 280 | SET NOCOUNT ON 281 | IF @Search IS NULL 282 | SELECT CustomerTypeID, CustomerTypeName, DiscountPercent,[Default] 283 | FROM dbo.CustomerType 284 | ORDER BY CustomerTypeName 285 | ELSE 286 | BEGIN 287 | SELECT CustomerTypeID, CustomerTypeName, DiscountPercent,[Default] 288 | FROM dbo.CustomerType 289 | WHERE CustomerTypeName = @Search 290 | IF @@ROWCOUNT = 0 291 | RAISERROR('Name ''%s'' Not Found.',14,1,@Search) 292 | END 293 | go 294 | 295 | CREATE PROCEDURE pCustomerType_Delete( 296 | @CustomerTypeID UNIQUEIDENTIFIER 297 | ) 298 | AS 299 | SET NOCOUNT ON 300 | DECLARE 301 | @ProductCategoryID UNIQUEIDENTIFIER, 302 | @Err INT, 303 | @ErrCounter INT 304 | SET @ErrCounter = 0 305 | DELETE dbo.CustomerType 306 | WHERE CustomerTypeID = @CustomerTypeID 307 | RETURN 308 | 309 | go 310 | 311 | ----------------------------------------------------------------- 312 | -- Contact Sprocs 313 | ----------------------------------------------------------------- 314 | 315 | CREATE PROCEDURE pContact_AddNew( 316 | @ContactCode NVARCHAR(20), 317 | @LastName NVARCHAR(50), 318 | @FirstName NVARCHAR(50), 319 | @CompanyName NVARCHAR(50) = NULL, 320 | @Name NVARCHAR(50) = NULL 321 | ) 322 | AS 323 | SET NOCOUNT ON 324 | DECLARE 325 | @CustomerTypeID UNIQUEIDENTIFIER, 326 | @Err INT 327 | 328 | SELECT @CustomerTypeID = CustomerTypeID 329 | FROM dbo.CustomerType 330 | WHERE CustomerTypeName = @Name 331 | IF @@Error <> 0 RETURN -100 332 | 333 | IF @CustomerTypeID IS NULL 334 | SELECT @CustomerTypeID = CustomerTypeID 335 | FROM dbo.CustomerType 336 | WHERE [Default] = 1 337 | IF @@Error <> 0 RETURN -100 338 | IF @CustomerTypeID IS NULL 339 | BEGIN 340 | RAISERROR ('Customer Type: ''%s'' not found', 15,1,@Name) 341 | RETURN -100 342 | END 343 | 344 | INSERT dbo.Contact ( 345 | ContactCode,SoundexCode, LastName, 346 | FirstName, CompanyName, CustomerTypeID) 347 | VALUES ( 348 | @ContactCode, SOUNDEX(@LastName), @LastName, 349 | @FirstName, @CompanyName, @CustomerTypeID) 350 | IF @@Error <> 0 RETURN -100 351 | 352 | RETURN 0 353 | 354 | go 355 | 356 | 357 | ---------------------------------------------------------- 358 | CREATE PROCEDURE pContactSetEmployee( 359 | @ContactCode VARCHAR(15) 360 | ) 361 | AS 362 | SET NOCOUNT ON 363 | UPDATE dbo.Contact 364 | SET IsEmployee = 1 365 | WHERE ContactCode = @ContactCode 366 | IF @@RowCount = 0 367 | RAISERROR('Contact %s not updated.',16,1,@ContactCode) 368 | 369 | go 370 | ----------------------------------------------------------- 371 | CREATE PROCEDURE pContactClearEmployee( 372 | @ContactCode VARCHAR(15) 373 | ) 374 | AS 375 | SET NOCOUNT ON 376 | UPDATE dbo.Contact 377 | SET IsEmployee = 0 378 | WHERE ContactCode = @ContactCode 379 | IF @@RowCount = 0 380 | RAISERROR('Contact %s not updated.',16,1,@ContactCode) 381 | go 382 | 383 | 384 | 385 | ----------------------------------------------------------------- 386 | -- Product sprocs 387 | ----------------------------------------------------------------- 388 | 389 | CREATE PROCEDURE pProduct_AddNew( 390 | @ProductCategoryName NVARCHAR(50), 391 | @Code CHAR(10), 392 | @Name NVARCHAR(50), 393 | @ProductDescription NVARCHAR(100) = NULL 394 | ) 395 | AS 396 | SET NOCOUNT ON 397 | DECLARE 398 | @ProductCategoryID UNIQUEIDENTIFIER 399 | 400 | SELECT @ProductCategoryID = ProductCategoryID 401 | FROM dbo.ProductCategory 402 | WHERE ProductCategoryName = @ProductCategoryName 403 | IF @@Error <> 0 RETURN -100 404 | 405 | IF @ProductCategoryID IS NULL 406 | BEGIN 407 | RAISERROR ('Product Category: ''%s'' not found', 15,1,@ProductCategoryName) 408 | RETURN -100 409 | END 410 | 411 | INSERT dbo.Product (ProductCategoryID, Code, ProductName, ProductDescription) 412 | VALUES (@ProductCategoryID, @Code, @Name, @ProductDescription ) 413 | IF @@Error <> 0 RETURN -100 414 | RETURN 0 415 | go 416 | 417 | -------------------------------------------------------- 418 | 419 | CREATE PROCEDURE pProduct_Fetch( 420 | @ProductCode CHAR(15) = NULL, 421 | @ProductCategory CHAR(15) = NULL ) 422 | AS 423 | SET NoCount ON 424 | 425 | SELECT Code, ProductName, ProductDescription, ActiveDate, 426 | DiscontinueDate, ProductCategoryName, [RowVersion] --, 427 | -- Product.Created, Product.Modified 428 | FROM Product 429 | JOIN ProductCategory 430 | ON Product.ProductCategoryID 431 | = ProductCategory.ProductCategoryID 432 | WHERE ( Product.Code = @ProductCode 433 | OR @ProductCode IS NULL ) 434 | AND ( ProductCategory.ProductCategoryName = @ProductCategory 435 | OR @ProductCategory IS NULL ) 436 | IF @@Error <> 0 RETURN -100 437 | 438 | RETURN 439 | 440 | go 441 | ------------------------------------- 442 | CREATE PROCEDURE pProduct_Update_RowVersion ( 443 | @Code CHAR(15), 444 | @RowVersion Rowversion, 445 | @Name VARCHAR(50), 446 | @ProductDescription VARCHAR(50), 447 | @ActiveDate DateTime, 448 | @DiscontinueDate DateTime ) 449 | AS 450 | SET NoCount ON 451 | 452 | UPDATE dbo.Product 453 | SET 454 | ProductName = @Name, 455 | ProductDescription = @ProductDescription, 456 | ActiveDate = @ActiveDate, 457 | DiscontinueDate = @DiscontinueDate 458 | WHERE Code = @Code 459 | AND [RowVersion] = @RowVersion 460 | 461 | IF @@ROWCOUNT = 0 462 | BEGIN 463 | IF EXISTS ( SELECT * FROM Product WHERE Code = @Code) 464 | BEGIN 465 | RAISERROR ('Product failed to update because another transaction updated the row since your last read.', 16,1) 466 | RETURN -100 467 | END 468 | ELSE 469 | BEGIN 470 | RAISERROR ('Product failed to update because the row has been deleted', 16,1) 471 | RETURN -100 472 | END 473 | END 474 | 475 | RETURN 476 | go 477 | 478 | ----------------------------------------- 479 | 480 | CREATE PROCEDURE pProduct_Update_Minimal ( 481 | @Code CHAR(15), 482 | @Name VARCHAR(50) = NULL, 483 | @ProductDescription VARCHAR(50) = NULL, 484 | @ActiveDate DateTime = NULL, 485 | @DiscontinueDate DateTime = NULL ) 486 | 487 | AS 488 | SET NoCount ON 489 | 490 | IF EXISTS (SELECT * FROM dbo.Product WHERE Code = @Code) 491 | BEGIN 492 | BEGIN TRANSACTION 493 | IF @Name IS NOT NULL 494 | BEGIN 495 | UPDATE dbo.Product 496 | SET 497 | ProductName = @Name 498 | WHERE Code = @Code 499 | IF @@Error <> 0 500 | BEGIN 501 | ROLLBACK 502 | RETURN -100 503 | END 504 | END 505 | 506 | IF @ProductDescription IS NOT NULL 507 | BEGIN 508 | UPDATE dbo.Product 509 | SET 510 | ProductDescription = @ProductDescription 511 | WHERE Code = @Code 512 | IF @@Error <> 0 513 | BEGIN 514 | ROLLBACK 515 | RETURN -100 516 | END 517 | END 518 | 519 | IF @ActiveDate IS NOT NULL 520 | BEGIN 521 | UPDATE dbo.Product 522 | SET 523 | ActiveDate = @ActiveDate 524 | WHERE Code = @Code 525 | IF @@Error <> 0 526 | BEGIN 527 | ROLLBACK 528 | RETURN -100 529 | END 530 | END 531 | 532 | IF @DiscontinueDate IS NOT NULL 533 | BEGIN 534 | UPDATE dbo.Product 535 | SET 536 | DiscontinueDate = @DiscontinueDate 537 | WHERE Code = @Code 538 | IF @@Error <> 0 539 | BEGIN 540 | ROLLBACK 541 | RETURN -100 542 | END 543 | END 544 | COMMIT TRANSACTION 545 | END 546 | ELSE 547 | BEGIN 548 | RAISERROR 549 | ('Product failed to update because the row has 550 | been deleted', 16,1) 551 | RETURN -100 552 | END 553 | RETURN 554 | 555 | go 556 | 557 | ----------------------------------------------------------------- 558 | CREATE PROCEDURE pProduct_Delete( 559 | @ProductCode INT 560 | ) 561 | AS 562 | SET NOCOUNT ON 563 | DECLARE @ProductID UniqueIdentifier 564 | 565 | SELECT @ProductID = ProductID 566 | FROM Product 567 | WHERE Code = @ProductCode 568 | If @@RowCount = 0 569 | BEGIN 570 | RAISERROR 571 | ('Unable to delete Product Code %i - does not exist.', 16,1, @ProductCode) 572 | RETURN 573 | END 574 | ELSE 575 | DELETE dbo.Product 576 | WHERE ProductID = @ProductID 577 | RETURN 578 | go 579 | ----------------------------------------------------------------- 580 | -- Location Sprocs 581 | ----------------------------------------------------------------- 582 | 583 | CREATE PROCEDURE pLocation_AddNew( 584 | @LocationCode CHAR(15), 585 | @LocationName NVARCHAR(50), 586 | @isRetail BIT 587 | ) 588 | AS 589 | SET NOCOUNT ON 590 | INSERT dbo.Location(LocationCode, LocationName, IsRetail) 591 | VALUES (@LocationCode, @LocationName, @IsRetail) 592 | IF @@Error <> 0 RETURN -100 593 | RETURN 594 | 595 | go 596 | 597 | 598 | ----------------------------------------------------------------- 599 | -- Price Sprocs 600 | ----------------------------------------------------------------- 601 | 602 | CREATE PROCEDURE pPrice_AddNew( 603 | @Code CHAR(10) = NULL, 604 | @Name NVARCHAR(50) = NULL, 605 | @Price MONEY, 606 | @EffectiveDate DATETIME = NULL) 607 | AS 608 | -- may specifiy either Product Code or Name 609 | -- re-inserting price for product and date will overwrite price row 610 | 611 | SET NOCOUNT ON 612 | DECLARE @ProductID UNIQUEIDENTIFIER 613 | 614 | IF @Code IS NOT NULL 615 | BEGIN 616 | SELECT @ProductID = ProductID 617 | FROM dbo.Product 618 | WHERE Code = @Code 619 | IF @ProductID IS NULL 620 | BEGIN 621 | RAISERROR ('Product: ''%s'' not found by code', 15,1,@Code) 622 | RETURN -1 623 | END 624 | END 625 | 626 | ELSE IF @Name IS NOT NULL 627 | BEGIN 628 | SELECT @ProductID = ProductID 629 | FROM dbo.Product 630 | WHERE ProductName = @Name 631 | IF @ProductID IS NULL 632 | BEGIN 633 | RAISERROR ('Product: ''%s'' not found by name', 15,1,@Name) 634 | RETURN -1 635 | END 636 | END 637 | 638 | INSERT dbo.Price (ProductID, Price, EffectiveDate) 639 | VALUES (@ProductID, @Price, @EffectiveDate) 640 | 641 | RETURN 0 642 | go 643 | 644 | 645 | 646 | ----------------------------------------------------------------- 647 | -- Order Entry Sprocs 648 | ----------------------------------------------------------------- 649 | 650 | CREATE PROCEDURE pGetPrice( 651 | @Code CHAR(10), 652 | @PriceDate DATETIME = NULL, 653 | @ContactCode CHAR(15) = NULL, 654 | @CurrPrice MONEY OUTPUT 655 | ) 656 | AS 657 | -- Will return the current price for the product for today or any other date 658 | -- The customer type determines the discount percentage 659 | -- the output parameter, @CurrPrice, will contain the effective price 660 | 661 | -- example code for calling this sproc: 662 | -- Declare @Price money 663 | -- EXEC GetPrice '1006', NULL, @Price OUTPUT 664 | -- Select @Price 665 | 666 | SET NOCOUNT ON 667 | DECLARE 668 | @DiscountPercent NUMERIC (4,2), 669 | @Err INT, 670 | @ErrCounter INT 671 | 672 | SET @ErrCounter = 0 673 | SET @CurrPrice = NULL 674 | 675 | LockTimeOutRetry: 676 | 677 | IF @PriceDate IS NULL 678 | SET @PriceDate = GETDATE() 679 | -- set the discount percent / if no customer lookup then it's zilch discount 680 | SELECT @DiscountPercent = CustomerType.DiscountPercent 681 | FROM dbo.Contact 682 | JOIN dbo.CustomerType 683 | ON contact.CustomerTypeID = CustomerType.CustomerTypeID 684 | WHERE ContactCode = @ContactCode 685 | SET @Err = @@ERROR 686 | IF @Err <> 0 GOTO ErrorHandler 687 | 688 | IF @DiscountPercent IS NULL 689 | SET @DiscountPercent = 0 690 | 691 | SELECT @CurrPrice = Price * (1-@DiscountPercent) 692 | FROM dbo.Price 693 | JOIN dbo.Product 694 | ON Price.ProductID = Product.ProductID 695 | WHERE Code = @Code 696 | AND EffectiveDate = 697 | (SELECT MAX(EffectiveDate) 698 | FROM dbo.Price 699 | JOIN dbo.Product 700 | ON Price.ProductID = Product.ProductID 701 | WHERE Code = @Code 702 | AND EffectiveDate <= @PriceDate) 703 | IF @CurrPrice IS NULL 704 | BEGIN 705 | RAISERROR('Code: ''%s'' has no established price.',15,1, @Code) 706 | RETURN -100 707 | END 708 | 709 | SET @Err = @@ERROR 710 | IF @Err <> 0 GOTO ErrorHandler 711 | RETURN 0 712 | 713 | ErrorHandler: 714 | IF (@Err = 1222 OR @Err = 1205) AND @ErrCounter = 5 715 | BEGIN 716 | RAISERROR ('Unable to Lock Data after five attempts.', 16,1) 717 | RETURN -100 718 | END 719 | IF @Err = 1222 OR @Err = 1205 -- Lock Timeout / Deadlock 720 | BEGIN 721 | WAITFOR DELAY '00:00:00.25' 722 | SET @ErrCounter = @ErrCounter + 1 723 | GOTO LockTimeOutRetry 724 | END 725 | -- else unknown error 726 | RAISERROR (@err, 16,1) WITH LOG 727 | RETURN -100 728 | go 729 | 730 | ----------------------------------------- 731 | 732 | CREATE FUNCTION dbo.fGetPrice ( 733 | @Code CHAR(10), 734 | @PriceDate DATETIME, 735 | @ContactCode CHAR(15) = NULL) 736 | RETURNS MONEY 737 | As 738 | -- sample calling code: 739 | -- Select dbo.fGetPrice('1006',GetDate()) 740 | -- Select dbo.fGetPrice('1001','5/1/2001',NULL) 741 | -- must specify date, GetDate() not allowed within function 742 | BEGIN 743 | DECLARE @CurrPrice MONEY 744 | DECLARE @DiscountPercent NUMERIC (4,2) 745 | -- set the discount percent / if no customer lookup then it's zilch discount 746 | SELECT @DiscountPercent = CustomerType.DiscountPercent 747 | FROM dbo.Contact 748 | JOIN dbo.CustomerType 749 | ON contact.CustomerTypeID = CustomerType.CustomerTypeID 750 | WHERE ContactCode = @ContactCode 751 | IF @DiscountPercent IS NULL 752 | SET @DiscountPercent = 0 753 | SELECT @CurrPrice = Price * (1-@DiscountPercent) 754 | FROM dbo.Price 755 | JOIN dbo.Product 756 | ON Price.ProductID = Product.ProductID 757 | WHERE Code = @Code 758 | AND EffectiveDate = 759 | (SELECT MAX(EffectiveDate) FROM dbo.Price JOIN dbo.Product ON Price.ProductID = Product.ProductID 760 | WHERE Code = @Code AND EffectiveDate <= @PriceDate) 761 | RETURN @CurrPrice 762 | END 763 | go 764 | 765 | ----------------------------------------- 766 | -- pOrder_AddNew creates a new order and assigns an OrderNumber 767 | 768 | CREATE PROC pOrder_AddNew ( 769 | @ContactCode CHAR(15) = 0, -- if default then non-tracked customer 770 | @EmployeeCode CHAR(15), 771 | @LocationCode CHAR(15), 772 | @OrderDate DATETIME = NULL, 773 | @OrderNumber INT OUTPUT 774 | ) 775 | AS 776 | -- Logic: 777 | -- If supplied, check CustomerID valid 778 | SET NOCOUNT ON 779 | DECLARE 780 | @ContactID UNIQUEIDENTIFIER, 781 | @OrderID UNIQUEIDENTIFIER, 782 | @LocationID UNIQUEIDENTIFIER, 783 | @EmployeeID UNIQUEIDENTIFIER, 784 | @Err INT, 785 | @ErrCounter INT 786 | 787 | SET @ErrCounter = 0 788 | 789 | LockTimeOutRetry: 790 | 791 | -- Set Customer ContactID 792 | IF @ContactCode = 0 793 | SET @ContactID = NULL 794 | ELSE 795 | BEGIN 796 | SELECT @ContactID = ContactID 797 | FROM dbo.Contact 798 | WHERE ContactCode = @ContactCode 799 | SET @Err = @@ERROR 800 | IF @Err <> 0 GOTO ErrorHandler 801 | IF @ContactID IS NULL 802 | BEGIN -- a customer was submitted but not found 803 | RAISERROR( 'CustomerCode: ''%s not found',15,1, @ContactCode) 804 | RETURN -100 805 | END 806 | END 807 | 808 | -- Set LocationID 809 | SELECT @LocationID = LocationID 810 | FROM dbo.Location 811 | WHERE LocationCode = @LocationCode 812 | SET @Err = @@ERROR 813 | IF @Err <> 0 GOTO ErrorHandler 814 | IF @LocationID IS NULL 815 | BEGIN -- Location not found 816 | RAISERROR('LocationCode: ''%s'' not found',15,1, @LocationCode) 817 | RETURN -100 818 | END 819 | IF EXISTS(SELECT * 820 | FROM dbo.Location 821 | WHERE LocationID = @LocationID 822 | AND IsRetail = 0) 823 | BEGIN -- Location not found 824 | RAISERROR('LocationCode: ''%s'' not retail',15,1, @LocationCode) 825 | RETURN -100 826 | END 827 | 828 | -- Set EmployeeID 829 | SELECT @EmployeeID = ContactID 830 | FROM dbo.Contact 831 | WHERE ContactCode = @EmployeeCode 832 | SET @Err = @@ERROR 833 | IF @Err <> 0 GOTO ErrorHandler 834 | IF @EmployeeCode IS NULL 835 | BEGIN -- Location not found 836 | RAISERROR('EmployeeCode: ''%s'' not found',15,1, @EmployeeCode) 837 | RETURN -100 838 | END 839 | 840 | -- OrderNumber 841 | SET @OrderID = NEWID() 842 | SET TRANSACTION ISOLATION LEVEL SERIALIZABLE 843 | BEGIN TRANSACTION 844 | SELECT @OrderNumber = Max(OrderNumber) + 1 845 | FROM [Order] 846 | SET @OrderNumber = ISNULL(@OrderNumber, 1) 847 | SET @Err = @@ERROR 848 | IF @Err <> 0 849 | BEGIN 850 | ROLLBACK TRANSACTION 851 | GOTO ErrorHandler 852 | END 853 | -- All OK Perform the Insert 854 | INSERT dbo.[Order] ( OrderID, ContactID, OrderNumber, EmployeeID, LocationID, OrderDate ) 855 | VALUES ( @OrderID, @ContactID,@OrderNumber, @EmployeeID, @LocationID, ISNULL(@OrderDate,GETDATE())) 856 | SET @Err = @@ERROR 857 | IF @Err <> 0 858 | BEGIN 859 | ROLLBACK TRANSACTION 860 | GOTO ErrorHandler 861 | END 862 | COMMIT TRANSACTION 863 | 864 | RETURN -- @OrderNumber already set 865 | 866 | ErrorHandler: 867 | IF (@Err = 1222 OR @Err = 1205) AND @ErrCounter = 5 868 | BEGIN 869 | RAISERROR ('Unable to Lock Data after five attempts.', 16,1) 870 | RETURN -100 871 | END 872 | IF @Err = 1222 OR @Err = 1205 -- Lock Timeout / Deadlock 873 | BEGIN 874 | WAITFOR DELAY '00:00:00.25' 875 | SET @ErrCounter = @ErrCounter + 1 876 | GOTO LockTimeOutRetry 877 | END 878 | -- else unknown error 879 | RAISERROR (@err, 16,1) WITH LOG 880 | RETURN -100 881 | 882 | go 883 | 884 | 885 | ----------------------------------------- 886 | CREATE PROCEDURE pOrder_AddItem( 887 | @OrderNumber CHAR(15), 888 | @Code CHAR(15) = 0, -- if default then non-stock Product 889 | @NonStockProduct NVARCHAR(256) = NULL, 890 | @Quantity NUMERIC(7,2), 891 | @UnitPrice MONEY = 0, -- If Default then lookup the Price 892 | @ShipRequestDate DATETIME = NULL, --default to Today 893 | @ShipComment NVARCHAR(256) = NULL -- optional 894 | ) 895 | AS 896 | 897 | DECLARE 898 | @OrderID UNIQUEIDENTIFIER, 899 | @ProductID UNIQUEIDENTIFIER, 900 | @ContactCode CHAR(15), 901 | @PriceDate DATETIME, 902 | @Err INT, 903 | @ErrCounter INT 904 | 905 | SET @ErrCounter = 0 906 | 907 | LockTimeOutRetry: 908 | 909 | -- Fetch OrderID 910 | SELECT @OrderID = OrderID 911 | FROM dbo.[Order] 912 | WHERE OrderNumber = @OrderNumber 913 | SET @Err = @@ERROR 914 | IF @Err <> 0 GOTO ErrorHandler 915 | 916 | -- Fetch ProductID 917 | SELECT @ProductID = ProductID 918 | FROM Product 919 | WHERE Code = @Code 920 | SET @Err = @@ERROR 921 | IF @Err <> 0 GOTO ErrorHandler 922 | 923 | --- Fetch Contact Code / PriceDate 924 | SELECT @ContactCode = ContactCode, @PriceDate = OrderDate 925 | FROM dbo.[Order] 926 | LEFT JOIN Contact 927 | ON [Order].ContactID = Contact.ContactID 928 | SET @Err = @@ERROR 929 | IF @Err <> 0 GOTO ErrorHandler 930 | 931 | -- Fetch UnitPrice 932 | IF @UnitPrice IS NULL 933 | EXEC pGetPrice 934 | @Code, @PriceDate, @ContactCode, @UnitPrice OUTPUT 935 | -- Alternate GetPrice function method 936 | -- SET @UnitPrice = dbo.fGetPrice (@Code,@PriceDate, @ContactCode) 937 | SET @Err = @@ERROR 938 | IF @Err <> 0 GOTO ErrorHandler 939 | IF @UnitPrice IS NULL 940 | BEGIN 941 | RAISERROR( 942 | 'Code: ''%s'' has no established price.',15,1, @Code) 943 | RETURN -1 944 | END 945 | 946 | 947 | -- Set ShipRequestDate 948 | IF @ShipRequestDate IS NULL 949 | SET @ShipRequestDate = @PriceDate 950 | -- Do the insert 951 | INSERT OrderDetail( 952 | OrderID, ProductID, NonStockProduct, Quantity, 953 | UnitPrice, ShipRequestDate, ShipComment) 954 | VALUES ( 955 | @OrderID, @ProductID, @NonStockProduct, @Quantity, 956 | @UnitPrice, @ShipRequestDate, @ShipComment) 957 | SET @Err = @@ERROR 958 | IF @Err <> 0 GOTO ErrorHandler 959 | 960 | RETURN 0 961 | 962 | ErrorHandler: 963 | IF (@Err = 1222 OR @Err = 1205) AND @ErrCounter = 5 964 | BEGIN 965 | RAISERROR ( 966 | 'Unable to Lock Data after five attempts.', 16,1) 967 | RETURN -100 968 | END 969 | IF @Err = 1222 OR @Err = 1205 -- Lock Timeout / Deadlock 970 | BEGIN 971 | WAITFOR DELAY '00:00:00.25' 972 | SET @ErrCounter = @ErrCounter + 1 973 | GOTO LockTimeOutRetry 974 | END 975 | -- else unknown error 976 | RAISERROR (@err, 16,1) WITH LOG 977 | RETURN -100 978 | 979 | 980 | 981 | go 982 | 983 | 984 | ------------------------------------------------------- 985 | CREATE PROCEDURE pOrderPriority_AddNew( 986 | @OrderPriorityName NVARCHAR(15), 987 | @OrderPriorityCode NVARCHAR(15), 988 | @Priority INT 989 | ) 990 | AS 991 | SET NOCOUNT ON 992 | INSERT OrderPriority (OrderPriorityName, OrderPriorityCode, Priority) 993 | Values (@OrderPriorityName, @OrderPriorityCode, @Priority) 994 | go 995 | 996 | -------------------------------------------------------- 997 | CREATE PROCEDURE pOrder_SetPriority( 998 | @OrderNumber INT, 999 | @OrderPriorityCode NVARCHAR(15) 1000 | ) 1001 | AS 1002 | SET NOCOUNT ON 1003 | DECLARE @OrderPriorityID UNIQUEIDENTIFIER, 1004 | @OrderID UNIQUEIDENTIFIER 1005 | SELECT @OrderPriorityID = OrderPriorityID 1006 | FROM dbo.OrderPriority 1007 | WHERE OrderPriorityCode = @OrderPriorityCode 1008 | -- Check OrderPriorityCode 1009 | IF @OrderPriorityCode IS NULL 1010 | BEGIN 1011 | RAISERROR('Invalid OrderPriorityCode',14,1) 1012 | RETURN 1 1013 | END 1014 | -- Fetch OrderID 1015 | SELECT @OrderID = OrderID 1016 | FROM dbo.[Order] 1017 | WHERE OrderNumber = @OrderNumber 1018 | -- Check OrderNumber 1019 | IF @OrderID IS NULL 1020 | BEGIN 1021 | RAISERROR('Invalid OrderNumber',14,1) 1022 | RETURN 1 1023 | END 1024 | UPDATE [Order] 1025 | SET OrderPriorityID = @OrderPriorityID 1026 | WHERE OrderID = @OrderID 1027 | 1028 | 1029 | 1030 | 1031 | 1032 | 1033 | 1034 | 1035 | go 1036 | ----------------------------------------------------------- 1037 | -- Standard Utility Procs 1038 | 1039 | CREATE VIEW dbo.vTableRowCount 1040 | as 1041 | SELECT TOP 100 PERCENT dbo.sysobjects.[name], dbo.sysindexes.[rows] 1042 | FROM dbo.sysindexes 1043 | JOIN dbo.sysobjects 1044 | ON dbo.sysindexes.[id] = dbo.sysobjects.[id] 1045 | WHERE (dbo.sysobjects.xtype = 'U') 1046 | AND (dbo.sysindexes.indid = 0 1047 | OR dbo.sysindexes.indid = 1) 1048 | ORDER BY dbo.sysindexes.[name] 1049 | go 1050 | 1051 | 1052 | CREATE PROC sp_GetLocks 1053 | AS 1054 | Create Table #locks 1055 | (spid INT, 1056 | dbid INT, 1057 | objid INT, 1058 | indid INT, 1059 | type CHAR(5), 1060 | Resource NVARCHAR(255), 1061 | Mode NVARCHAR(255), 1062 | Status NVARCHAR(255)) 1063 | 1064 | INSERT #Locks EXEC sp_lock 1065 | 1066 | SELECT P.loginame, P.spid, l.dbid AS 'database', S.NAME AS 'Object' ,P.cmd, 1067 | l.type AS 'LockSize', l.mode AS 'lockMode', l.status, P.blocked, P.waittime 1068 | FROM #Locks L 1069 | Join sysobjects S 1070 | ON L.ObjID = S.ID 1071 | Join Master.dbo.sysprocesses P 1072 | ON L.spid = P.spid 1073 | ORDER BY p.loginame,P.spid, P.dbid, s.NAME 1074 | 1075 | RETURN 1076 | 1077 | 1078 | go 1079 | 1080 | USE TempDB 1081 | 1082 | -------------------------------------------------------------------------------- /OBXKites/OBXKites_Populate.sql: -------------------------------------------------------------------------------- 1 | 2 | ----------------------------------------------------------- 3 | -- OBX Kites Sample Database - POPULATE 4 | 5 | -- this script will insert sample data into the OBXKites Database 6 | 7 | -- The following script must be run prior to this script: 8 | -- OBXKites_Create 9 | 10 | Use OBXKites 11 | 12 | SET NOCOUNT ON 13 | 14 | Delete OrderDetail 15 | Delete [Order] 16 | Delete Contact 17 | Delete CustomerType 18 | Delete Price 19 | Delete Product 20 | Delete ProductCategory 21 | Delete Location 22 | Delete OrderPriority 23 | 24 | ----------------------------------------------------------- 25 | ----------------------------------------------------------- 26 | -- Product Categories 27 | 28 | EXEC pProductCategory_AddNew 'Kite', 'a variety of kites, from simple to stunt, to Chinese, to novelty kites' 29 | EXEC pProductCategory_AddNew 'Accessory', 'kite flying accessories' 30 | EXEC pProductCategory_AddNew 'Video', 'stunt kite contexts and lessons, and Outer Banks videos' 31 | EXEC pProductCategory_AddNew 'Book', 'Outer Banks books' 32 | EXEC pProductCategory_AddNew 'Material', 'Kite construction material' 33 | EXEC pProductCategory_AddNew 'OBX', 'OBX stuff' 34 | EXEC pProductCategory_AddNew 'Toy', 'Kids stuff' 35 | EXEC pProductCategory_AddNew 'Clothing', 'OBX t-shirts, hats, jackets' 36 | 37 | ----------------------------------------------------------- 38 | -- Products 39 | EXEC pProduct_AddNew 'Kite', '1001', 'Basic Box Kite 21 inch','' 40 | EXEC pProduct_AddNew 'Kite', '1002', 'Dragon Flight','' 41 | EXEC pProduct_AddNew 'Kite', '1003', 'Sky Dancer','' 42 | EXEC pProduct_AddNew 'Kite', '1004', 'Rocket Kite','' 43 | EXEC pProduct_AddNew 'Kite', '1005', 'Eagle Wings','' 44 | EXEC pProduct_AddNew 'Kite', '1006', 'Chinese 6" Kite','' 45 | EXEC pProduct_AddNew 'Kite', '1007', 'Grand Spiral','' 46 | EXEC pProduct_AddNew 'Kite', '1008', 'Sky Dancer 2','' 47 | EXEC pProduct_AddNew 'Kite', '1009', 'Air Writer 36','' 48 | EXEC pProduct_AddNew 'Kite', '1010', 'Air Writer 48','' 49 | EXEC pProduct_AddNew 'Kite', '1011', 'Air Writer 66','' 50 | EXEC pProduct_AddNew 'Kite', '1012', 'Falcon F-16','' 51 | EXEC pProduct_AddNew 'Kite', '1013', 'Eagle F-15','' 52 | EXEC pProduct_AddNew 'Kite', '1014', 'Pirate Ship in the Sky','' 53 | EXEC pProduct_AddNew 'Kite', '1015', 'Raider in the Sky','' 54 | EXEC pProduct_AddNew 'Kite', '1016', 'Original Diamond Kite','' 55 | EXEC pProduct_AddNew 'Kite', '1017', 'Competition 36"','' 56 | EXEC pProduct_AddNew 'Kite', '1018', 'Competition Pro 48"','' 57 | EXEC pProduct_AddNew 'Kite', '1019', 'Grand Daddy','' 58 | EXEC pProduct_AddNew 'Kite', '1020', 'Black Ghost','' 59 | EXEC pProduct_AddNew 'Accessory', '1021', 'Short Twirl','' 60 | EXEC pProduct_AddNew 'Accessory', '1022', 'Long Twirl','' 61 | EXEC pProduct_AddNew 'Accessory', '1023', 'Short Streamer','' 62 | EXEC pProduct_AddNew 'Accessory', '1024', 'Long Streamer','' 63 | EXEC pProduct_AddNew 'Accessory', '1025', 'Night Glow Streamers','' 64 | EXEC pProduct_AddNew 'Accessory', '1026', 'Handle','' 65 | EXEC pProduct_AddNew 'Accessory', '1027', 'Third Line Release','' 66 | EXEC pProduct_AddNew 'Accessory', '1028', 'High Performance Line','' 67 | EXEC pProduct_AddNew 'Accessory', '1029', 'Kite Bag','' 68 | EXEC pProduct_AddNew 'Accessory', '1030', 'Kite Repair Kit','' 69 | EXEC pProduct_AddNew 'Video', '1031', 'Basic Kite Flight','' 70 | EXEC pProduct_AddNew 'Video', '1032', '2001 July 4th Competition','' 71 | EXEC pProduct_AddNew 'Video', '1033', '2000 Wright Brothers Memorial FlyIn','' 72 | EXEC pProduct_AddNew 'Video', '1034', 'Advanced Acrobatics','' 73 | EXEC pProduct_AddNew 'Video', '1035', 'Kite Demos','' 74 | EXEC pProduct_AddNew 'Book', '1036', 'Adventures in the OuterBanks','' 75 | EXEC pProduct_AddNew 'Book', '1037', 'Wright Brothers Kite Designs','' 76 | EXEC pProduct_AddNew 'Book', '1038', 'The Lighthouses of the Outer Banks','' 77 | EXEC pProduct_AddNew 'Book', '1039', 'Outer Banks Map','' 78 | EXEC pProduct_AddNew 'Book', '1040', 'Kiters Guide to the Outer Banks','' 79 | EXEC pProduct_AddNew 'Material', '1041', 'Kite Fabric #6','' 80 | EXEC pProduct_AddNew 'Material', '1042', 'Kite Fabric #8','' 81 | EXEC pProduct_AddNew 'Material', '1043', 'Super Strutts','' 82 | EXEC pProduct_AddNew 'OBX', '1044', 'OBX Car Bumper Sticker','' 83 | EXEC pProduct_AddNew 'OBX', '1045', 'OBX Car Window Decal','' 84 | EXEC pProduct_AddNew 'OBX', '1046', 'OBX Postcard set','' 85 | EXEC pProduct_AddNew 'OBX', '1047', 'OBX Light Houses Poster','' 86 | EXEC pProduct_AddNew 'OBX', '1048', 'OBX/Kite Poster','' 87 | EXEC pProduct_AddNew 'Toy', '1049', 'Wright Brothers Model Plane','' 88 | EXEC pProduct_AddNew 'Toy', '1050', 'Spinner Hilo','' 89 | EXEC pProduct_AddNew 'Clothing', '1051', 'Cape Hatteras T-Shirt','' 90 | EXEC pProduct_AddNew 'Clothing', '1052', 'OBX T-Shirt','' 91 | EXEC pProduct_AddNew 'Clothing', '1053', 'OBX BallCap','' 92 | EXEC pProduct_AddNew 'Clothing', '1054', 'Go Fly a Kite T-Shirt','' 93 | EXEC pProduct_AddNew 'Clothing', '1055', 'OBX National Seashore BallCap','' 94 | 95 | ----------------------------------------------------------- 96 | -- Prices 97 | 98 | --Basic Box Kite 21 inch 99 | EXEC pPrice_AddNew 1001, NULL, 14.95, '05/01/2001' 100 | EXEC pPrice_AddNew NULL, 'Basic Box Kite 21 inch', 15.95, '06/01/2002' 101 | EXEC pPrice_AddNew NULL, 'Basic Box Kite 21 inch', 17.95, '7/20/2002' 102 | 103 | --Dragon Flight 104 | EXEC pPrice_AddNew 1002, NULL, 26.95, '05/01/2001' 105 | EXEC pPrice_AddNew NULL, 'Dragon Flight', 29.95, '5/20/2002' 106 | EXEC pPrice_AddNew NULL, 'Dragon Flight', 31.95, '5/20/2003' 107 | 108 | --Sky Dancer 109 | EXEC pPrice_AddNew NULL, 'Sky Dancer', 18.95, '05/01/2001' 110 | EXEC pPrice_AddNew 1003, NULL, 19.95, '5/20/2002' 111 | EXEC pPrice_AddNew 1003, NULL, 20.95, '5/20/2003' 112 | 113 | --Rocket Kite 114 | EXEC pPrice_AddNew 1004, NULL, 29.95, '05/01/2001' 115 | EXEC pPrice_AddNew NULL, 'Rocket Kite', 32.95, '05/01/2002' 116 | EXEC pPrice_AddNew NULL, 'Rocket Kite', 35.95, '5/20/2003' 117 | 118 | --Eagle Wings 119 | EXEC pPrice_AddNew 1005, NULL, 65.00, '05/01/2001' 120 | EXEC pPrice_AddNew 1005, NULL, 69.00, '05/01/2002' 121 | 122 | --Chinese 6 foot Kite 123 | EXEC pPrice_AddNew 1006, NULL, 119.95, '05/01/2001' 124 | EXEC pPrice_AddNew 1006, NULL, 125.95, '5/20/2002' 125 | EXEC pPrice_AddNew 1006, NULL, 131.95, '5/20/2003' 126 | 127 | --Grand Spiral 128 | EXEC pPrice_AddNew NULL, 'Grand Spiral', 12.95, '05/01/2001' 129 | EXEC pPrice_AddNew 1007, NULL, 15.95, '5/20/2002' 130 | EXEC pPrice_AddNew 1007, NULL, 16.45, '5/20/2003' 131 | 132 | --Sky Dancer 2 133 | EXEC pPrice_AddNew 1008, NULL, 26.95, '05/01/2001' 134 | EXEC pPrice_AddNew NULL, 'Sky Dancer 2', 28.95, '05/01/2002' 135 | EXEC pPrice_AddNew NULL, 'Sky Dancer 2', 29.95, '5/20/2003' 136 | 137 | --Air Writer 36 138 | EXEC pPrice_AddNew 1009, NULL, 54.95, '05/01/2001' 139 | EXEC pPrice_AddNew 1009, NULL, 57.95, '05/01/2002' 140 | EXEC pPrice_AddNew 1009, NULL, 59.95, '07/14/2002' 141 | EXEC pPrice_AddNew 1009, NULL, 62.95, '05/01/2003' 142 | 143 | --Air Writer 48 144 | EXEC pPrice_AddNew 1010, NULL, 74.95, '05/01/2001' 145 | EXEC pPrice_AddNew 1010, NULL, 77.95, '05/20/2002' 146 | EXEC pPrice_AddNew 1010, NULL, 81.95, '05/20/2003' 147 | 148 | --Air Writer 66 149 | EXEC pPrice_AddNew 1011, NULL, 112.95, '05/01/2001' 150 | EXEC pPrice_AddNew NULL, 'Air Writer 66', 119.95, '5/20/2002' 151 | EXEC pPrice_AddNew NULL, 'Air Writer 66', 125.95, '5/20/2003' 152 | 153 | --Falcon F-16 154 | EXEC pPrice_AddNew 1012, NULL, 49.95, '05/01/2001' 155 | 156 | --Eagle F-15 157 | EXEC pPrice_AddNew 1013, NULL, 49.95, '05/01/2001' 158 | EXEC pPrice_AddNew NULL, 'Eagle F-15', 52.95, '5/20/2002' 159 | 160 | --Pirate Ship in the Sky 161 | EXEC pPrice_AddNew 1014, NULL, 79.95, '05/01/2001' 162 | EXEC pPrice_AddNew NULL, 'Pirate Ship in the Sky', 74.95, '05/01/2002' 163 | EXEC pPrice_AddNew NULL, 'Pirate Ship in the Sky', 77.95, '5/20/2003' 164 | 165 | --Raider in the Sky 166 | EXEC pPrice_AddNew 1015, NULL, 22.95, '05/01/2001' 167 | EXEC pPrice_AddNew NULL, 'Raider in the Sky', 19.95, '5/20/2002' 168 | 169 | --Original Diamond Kite 170 | EXEC pPrice_AddNew 1016, NULL, 9.95, '05/01/2001' 171 | EXEC pPrice_AddNew NULL, 'Original Diamond Kite', 8.95, '07/01/2002' 172 | EXEC pPrice_AddNew NULL, 'Original Diamond Kite', 8.95, '07/08/2002' 173 | EXEC pPrice_AddNew NULL, 'Original Diamond Kite', 9.95, '05/01/2003' 174 | EXEC pPrice_AddNew NULL, 'Original Diamond Kite', 10.95, '5/20/2004' 175 | 176 | --Competition 36" 177 | EXEC pPrice_AddNew 1017, NULL, 225.95, '05/01/2001' 178 | EXEC pPrice_AddNew NULL, 'Competition 36"', 245.95, '5/20/2003' 179 | 180 | --Competition Pro 48" 181 | EXEC pPrice_AddNew 1018, NULL, 284.95, '05/01/2001' 182 | EXEC pPrice_AddNew NULL, 'Competition Pro 48"', 264.95, '05/01/2002' 183 | EXEC pPrice_AddNew NULL, 'Competition Pro 48"', 173.95, '5/20/2003' 184 | 185 | --Grand Daddy 186 | EXEC pPrice_AddNew NULL, 'Grand Daddy', 29.95, '05/01/2001' 187 | EXEC pPrice_AddNew 1019, NULL, 27.95, '5/20/2002' 188 | 189 | --Black Ghost 190 | EXEC pPrice_AddNew 1020, NULL, 29.95, '05/01/2001' 191 | 192 | --Short Twirl 193 | EXEC pPrice_AddNew 1021, NULL, 1.95, '05/01/2001' 194 | 195 | --Long Twirl 196 | EXEC pPrice_AddNew 1022, NULL, 2.65, '05/01/2001' 197 | EXEC pPrice_AddNew 1022, NULL, 2.95, '5/20/2002' 198 | 199 | --Short Streamer 200 | EXEC pPrice_AddNew 1023, NULL, 1.95, '05/01/2001' 201 | EXEC pPrice_AddNew NULL, 'Short Streamer', 2.95, '5/20/2002' 202 | 203 | --Long Streamer 204 | EXEC pPrice_AddNew 1024, NULL, 1.95, '05/01/2001' 205 | EXEC pPrice_AddNew NULL, 'Long Streamer', 2.45, '5/20/2002' 206 | 207 | --Night Glow Streamers 208 | EXEC pPrice_AddNew 1025, NULL, 5.95, '05/01/2001' 209 | EXEC pPrice_AddNew NULL, 'Night Glow Streamers', 6.95, '5/20/2002' 210 | EXEC pPrice_AddNew NULL, 'Night Glow Streamers', 7.95, '5/20/2003' 211 | 212 | --Handle 213 | EXEC pPrice_AddNew 1026, NULL, 8.95, '05/01/2001' 214 | EXEC pPrice_AddNew NULL, 'Handle', 9.95, '5/20/2003' 215 | 216 | --Third Line Release 217 | EXEC pPrice_AddNew 1027, NULL, 15.95, '05/01/2001' 218 | EXEC pPrice_AddNew NULL, 'Third Line Release', 13.45, '5/20/2002' 219 | EXEC pPrice_AddNew NULL, 'Third Line Release', 14.95, '5/20/2003' 220 | 221 | --High Performance Line 222 | EXEC pPrice_AddNew 1028, NULL, 10.95, '05/01/2001' 223 | EXEC pPrice_AddNew NULL, 'High Performance Line', 12.95, '5/20/2002' 224 | 225 | --Kite Bag 226 | EXEC pPrice_AddNew 1029, NULL, 8.95, '05/01/2001' 227 | EXEC pPrice_AddNew NULL, 'Kite Bag', 9.95, '5/20/2002' 228 | EXEC pPrice_AddNew NULL, 'Kite Bag', 11.95, '5/20/2003' 229 | 230 | --Kite Repair Kit 231 | EXEC pPrice_AddNew 1030, NULL, 1.95, '05/01/2001' 232 | 233 | --Basic Kite Flight 234 | EXEC pPrice_AddNew 1031, NULL, 6.95, '05/01/2001' 235 | EXEC pPrice_AddNew 1031, NULL, 7.95, '05/20/2002' 236 | EXEC pPrice_AddNew 1031, NULL, 6.95, '07/01/2002' 237 | EXEC pPrice_AddNew 1031, NULL, 7.95, '07/10/2002' 238 | EXEC pPrice_AddNew 1031, NULL, 8.95, '05/20/2003' 239 | 240 | --2001 July 4th Competition 241 | EXEC pPrice_AddNew 1032, NULL, 19.95, '05/01/2001' 242 | 243 | --2000 Wright Brothers Memorial FlyIn 244 | EXEC pPrice_AddNew 1033, NULL, 19.95, '05/01/2001' 245 | 246 | 247 | --Advanced Acrobatics 248 | EXEC pPrice_AddNew 1034, NULL, 19.95, '05/01/2001' 249 | 250 | --Kite Demos 251 | EXEC pPrice_AddNew 1035, NULL, 19.95, '05/01/2001' 252 | EXEC pPrice_AddNew NULL, 'Kite Demos', 14.95, '5/20/2002' 253 | 254 | --Adventures in the OuterBanks 255 | EXEC pPrice_AddNew 1036, NULL, 7.95, '05/01/2001' 256 | EXEC pPrice_AddNew 1036, NULL, 8.95, '07/01/2003' 257 | 258 | --Wright Brothers Kite Designs 259 | EXEC pPrice_AddNew NULL, 'Wright Brothers Kite Designs', 29.95, '5/20/2002' 260 | 261 | --The Lighthouses of the Outer Banks 262 | EXEC pPrice_AddNew 1038, NULL, 14.95, '05/01/2001' 263 | EXEC pPrice_AddNew NULL, 'The Lighthouses of the Outer Banks', 16.95, '5/20/2002' 264 | 265 | --Outer Banks Map 266 | EXEC pPrice_AddNew 1039, NULL, 2.95, '05/01/2001' 267 | EXEC pPrice_AddNew NULL, 'Outer Banks Map', 3.95, '5/20/2002' 268 | 269 | --Kiters Guide to the Outer Banks 270 | EXEC pPrice_AddNew 1040, NULL, 9.95, '05/01/2001' 271 | EXEC pPrice_AddNew NULL, 'Kiters Guide to the Outer Banks', 8.95, '5/20/2002' 272 | 273 | --Kite Fabric #6 274 | EXEC pPrice_AddNew 1041, NULL, .95, '05/01/2001' 275 | 276 | --Kite Fabric #8 277 | EXEC pPrice_AddNew 1042, NULL, .95, '05/01/2001' 278 | EXEC pPrice_AddNew NULL, 'Kite Fabric #8', 1.05, '5/20/2002' 279 | 280 | --Super Strutts 281 | EXEC pPrice_AddNew 1043, NULL, 1.95, '05/01/2001' 282 | EXEC pPrice_AddNew NULL, 'Super Strutts', 12.25, '5/20/2002' 283 | 284 | --OBX Car Bumper Sticker 285 | EXEC pPrice_AddNew 1044, NULL, .75, '05/01/2001' 286 | 287 | --OBX Car Window Decal 288 | EXEC pPrice_AddNew 1045, NULL, .75, '5/20/2001' 289 | EXEC pPrice_AddNew 1045, NULL, .95, '5/20/2002' 290 | 291 | --OBX Postcard set 292 | EXEC pPrice_AddNew 1046, NULL, 1.95, '05/01/2001' 293 | 294 | --OBX Light Houses Poster 295 | EXEC pPrice_AddNew 1047, NULL, 6.95, '05/01/2001' 296 | EXEC pPrice_AddNew 1047, NULL, 7.95, '5/20/2002' 297 | EXEC pPrice_AddNew 1047, NULL, 8.95, '5/20/2003' 298 | 299 | --OBX/Kite Poster 300 | EXEC pPrice_AddNew 1048, NULL, 6.95, '05/01/2001' 301 | EXEC pPrice_AddNew NULL, 'OBX/Kite Poster', 7.95, '5/20/2002' 302 | 303 | --Wright Brothers Model Plane 304 | EXEC pPrice_AddNew 1049, NULL, 12.95, '05/01/2001' 305 | EXEC pPrice_AddNew NULL, 'Wright Brothers Model Plane', 14.95, '5/20/2002' 306 | 307 | --Spinner Hilo 308 | EXEC pPrice_AddNew 1050, NULL, 4.95, '05/01/2001' 309 | EXEC pPrice_AddNew NULL, 'Spinner Hilo', 5.45, '05/01/2001' 310 | EXEC pPrice_AddNew NULL, 'Spinner Hilo', 5.95, '5/20/2002' 311 | 312 | --Cape Hatteras T-Shirt 313 | EXEC pPrice_AddNew 1051, NULL, 14.95, '05/01/2001' 314 | EXEC pPrice_AddNew NULL, 'Cape Hatteras T-Shirt', 16.95, '5/20/2002' 315 | 316 | --OBX T-Shirt 317 | EXEC pPrice_AddNew 1052, NULL, 14.95, '05/01/2001' 318 | EXEC pPrice_AddNew NULL, 'OBX T-Shirt', 16.95, '5/20/2002' 319 | 320 | --OBX BallCap 321 | EXEC pPrice_AddNew 1054, NULL, 11.95, '05/01/2001' 322 | 323 | --Go Fly a Kite T-Shirt 324 | EXEC pPrice_AddNew 1054, NULL, 8.95, '05/01/2001' 325 | EXEC pPrice_AddNew NULL, 'Go Fly a Kite T-Shirt', 9.95, '5/20/2002' 326 | 327 | --OBX National Seashore BallCap 328 | EXEC pPrice_AddNew 1055, NULL, 13.95, '05/01/2001' 329 | EXEC pPrice_AddNew NULL, 'OBX National Seashore BallCap', 14.95, '5/20/2002' 330 | 331 | 332 | ----------------------------------------------------------- 333 | -- Customer Types 334 | EXEC pCustomerType_AddNew 'Preferred', .10 335 | EXEC pCustomerType_AddNew 'Wholesale', .15 336 | EXEC pCustomerType_AddNew 'Retail',0,1 -- set this CustomerType to the default 337 | 338 | -- Contacts 339 | EXEC pContact_AddNew '101', 'Smith', 'Ulisius', NULL, 'Preferred' 340 | EXEC pContact_AddNew '102', 'Adams', 'Terri', NULL, 'Preferred' 341 | EXEC pContact_AddNew '103', 'Reagan', 'Steve', NULL, 'Preferred' 342 | EXEC pContact_AddNew '104', 'Franklin', 'Rondey', NULL, 'Preferred' 343 | EXEC pContact_AddNew '105', 'Dowdry', 'Quin', NULL, 'Preferred' 344 | EXEC pContact_AddNew '106', 'Grant', 'Peter', 'Southern Beach', 'Wholesale' 345 | EXEC pContact_AddNew '107', 'Smith', 'Oscar', 'Cape Hatteras General Store', 'Wholesale' 346 | EXEC pContact_AddNew '108', 'Hanks', 'Nickolas', 'Norfolk Kite Flight', 'Wholesale' 347 | EXEC pContact_AddNew '109', 'James', 'Mike', 'Boston Kites', 'Wholesale' 348 | EXEC pContact_AddNew '110', 'Kennedy', 'Lisa', 'Wright Brothers Memorial Store', 'Wholesale' 349 | EXEC pContact_AddNew '111', 'Williams', 'Kid', NULL, 'Retail' 350 | EXEC pContact_AddNew '112', 'Quincy', 'Jennifer', NULL, 'Retail' 351 | EXEC pContact_AddNew '113', 'Laudry', 'Irene', NULL, 'Retail' 352 | EXEC pContact_AddNew '114', 'Nelson', 'Harry', NULL, 'Retail' 353 | EXEC pContact_AddNew '115', 'Miller', 'Ginger', NULL, 'Retail' 354 | EXEC pContact_AddNew '116', 'Jamison', 'Frank', NULL -- use the default CustomerType 355 | EXEC pContact_AddNew '117', 'Andrews', 'Ed', NULL 356 | EXEC pContact_AddNew '118', 'Boston', 'Dave', NULL 357 | EXEC PContactSetEmployee '118' 358 | EXEC pContact_AddNew '119', 'Harrison', 'Charlie', NULL 359 | EXEC PContactSetEmployee '119' 360 | EXEC pContact_AddNew '120', 'Earl', 'Betty', NULL 361 | EXEC PContactSetEmployee '120' 362 | EXEC pContact_AddNew '121', 'Zing', 'Chei', NULL 363 | 364 | ----------------------------------------------------------- 365 | -- Location 366 | EXEC pLocation_AddNew 'CH', 'Cape Hatteras', 1 367 | EXEC pLocation_AddNew 'Clt', 'Charlotte', 1 368 | EXEC pLocation_AddNew 'ElC', 'Elizabeth City', 1 369 | EXEC pLocation_AddNew 'JR', 'Jockey''s Ridge', 1 370 | EXEC pLocation_AddNew 'KDH', 'Kill Devil Hills', 1 371 | EXEC pLocation_AddNew 'W', 'Warehouse', 0 372 | go 373 | 374 | ----------------------------------------------------------- 375 | -- Order Entry 376 | EXEC pOrderPriority_AddNew 'Rush', '1', '1' 377 | 378 | DECLARE @OrderNumber INT 379 | 380 | --Order 1 381 | EXEC pOrder_AddNew 382 | @ContactCode = '101', 383 | @EmployeeCode = '120', 384 | @LocationCode = 'CH', 385 | @OrderDate=NULL, 386 | @OrderNumber = @OrderNumber output 387 | 388 | EXEC pOrder_SetPriority @OrderNumber, '1' 389 | 390 | EXEC pOrder_AddItem 391 | @OrderNumber = @OrderNumber, -- must be a valid, open order. Get OrderNumber from pOrder_AddNew 392 | @Code = '1002', -- if NULL then non-stock Product text description 393 | @NonStockProduct = NULL, 394 | @Quantity = 12, -- required 395 | @UnitPrice = NULL, -- if Null then the sproc will lookup the correct current price for the customer 396 | @ShipRequestDate = '11/15/01', -- if NULL then today 397 | @ShipComment = NULL 398 | 399 | -- Order 2 400 | EXEC pOrder_AddNew '101', '120', 'CH', NULL, @OrderNumber output 401 | EXEC pOrder_AddItem @OrderNumber, '1002', NULL, 3, NULL, NULL, NULL 402 | EXEC pOrder_AddItem @OrderNumber, '1003', NULL, 5, NULL, NULL, NULL 403 | EXEC pOrder_AddItem @OrderNumber, '1004', NULL, 2, NULL, NULL, NULL 404 | EXEC pOrder_AddItem @OrderNumber, '1044', NULL, 1, NULL, NULL, NULL 405 | -- Order 3 406 | EXEC pOrder_AddNew '102', '120', 'CH', NULL, @OrderNumber output 407 | EXEC pOrder_AddItem @OrderNumber, '1002', NULL, 3, NULL, NULL, NULL 408 | EXEC pOrder_SetPriority @OrderNumber, '1' 409 | 410 | -- Order 4 411 | EXEC pOrder_AddNew '103', '119', 'JR', '11/15/01', @OrderNumber output 412 | EXEC pOrder_AddItem @OrderNumber, '1051', NULL, 6, NULL, NULL, NULL 413 | EXEC pOrder_AddItem @OrderNumber, '1012', NULL, 5, NULL, NULL, NULL 414 | EXEC pOrder_AddItem @OrderNumber, '1002', NULL, 4, NULL, NULL, NULL 415 | EXEC pOrder_AddItem @OrderNumber, '1023', NULL, 3, NULL, NULL, NULL 416 | EXEC pOrder_AddItem @OrderNumber, '1024', NULL, 2, NULL, NULL, NULL 417 | EXEC pOrder_AddItem @OrderNumber, '1023', NULL, 1, NULL, NULL, NULL 418 | EXEC pOrder_AddItem @OrderNumber, '1044', NULL, 1, NULL, NULL, NULL 419 | --Order 5 420 | EXEC pOrder_AddNew '101', '118', 'CH', '11/15/01', @OrderNumber output 421 | EXEC pOrder_AddItem @OrderNumber, '1032', NULL, 2, NULL, NULL, NULL 422 | EXEC pOrder_AddItem @OrderNumber, '1043', NULL, 3, NULL, NULL, NULL 423 | EXEC pOrder_AddItem @OrderNumber, '1044', NULL, 120, .50, '12/1/01', 'bulk ship to Mateo' 424 | -- Order 6 425 | EXEC pOrder_AddNew '102', '120', 'CH', NULL, @OrderNumber output 426 | EXEC pOrder_AddItem @OrderNumber, '1055', NULL, 1, NULL, NULL, NULL 427 | EXEC pOrder_AddItem @OrderNumber, '1044', NULL, 1, NULL, NULL, NULL 428 | -- Order 7 429 | EXEC pOrder_AddNew '103', '119', 'JR', NULL, @OrderNumber output 430 | EXEC pOrder_AddItem @OrderNumber, '1002', NULL, 2, NULL, NULL, NULL 431 | EXEC pOrder_AddItem @OrderNumber, '1002', NULL, 12, NULL, NULL, NULL 432 | EXEC pOrder_AddItem @OrderNumber, '1044', NULL, 1, NULL, NULL, NULL 433 | -- Order 8 434 | EXEC pOrder_AddNew '104', '118', 'CH', '11/15/01', @OrderNumber output 435 | EXEC pOrder_AddItem @OrderNumber, '1002', '11/21/01', 1, NULL, NULL, NULL 436 | EXEC pOrder_AddItem @OrderNumber, '1002', '11/21/01', 2, NULL, NULL, NULL 437 | EXEC pOrder_AddItem @OrderNumber, '1002', NULL, 1, NULL, NULL, NULL 438 | EXEC pOrder_AddItem @OrderNumber, '1044', NULL, 1, NULL, NULL, NULL 439 | -- Order 9 440 | EXEC pOrder_AddNew '105', '121', 'KDH', NULL, @OrderNumber output 441 | EXEC pOrder_AddItem @OrderNumber, '1002', NULL, 1, NULL, NULL, NULL 442 | EXEC pOrder_AddItem @OrderNumber, '1002', NULL, 3, NULL ,NULL, NULL 443 | EXEC pOrder_AddItem @OrderNumber, '1044', NULL, 1, NULL, NULL, NULL 444 | -- Order 10 445 | EXEC pOrder_AddNew '106', '121', 'KDH', NULL, @OrderNumber output 446 | EXEC pOrder_AddItem @OrderNumber, '1002', NULL, 1, NULL, NULL, NULL 447 | EXEC pOrder_AddItem @OrderNumber, '1002', NULL, 2, NULL, NULL, NULL 448 | EXEC pOrder_AddItem @OrderNumber, '1052', NULL, 1, NULL, NULL, NULL 449 | EXEC pOrder_AddItem @OrderNumber, '1054', NULL, 1, NULL, NULL, NULL 450 | EXEC pOrder_AddItem @OrderNumber, '1044', NULL, 1, NULL, NULL, NULL 451 | 452 | 453 | 454 | --Select * from [Order] 455 | --Select * from OrderDetail 456 | --Select dbo.fGetPrice ('1002',GetDate(), '101') 457 | --Select @OrderNumber 458 | --Select * from Price Join Product On Price.ProductID = Product.ProductID Where Code = '1003' 459 | 460 | -- Wrap Up 461 | Select * from vTableRowCount 462 | 463 | Use Master 464 | 465 | 466 | --------------------------------------------------------------------------------