├── Person common names reference.xlsx ├── Animal species and names reference.xlsx ├── README.TXT ├── 02 - Create animal shelter schema and data.sql └── 01 - Create database and reference data.sql /Person common names reference.xlsx: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/ami-levin/Animal_Shelter/HEAD/Person common names reference.xlsx -------------------------------------------------------------------------------- /Animal species and names reference.xlsx: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/ami-levin/Animal_Shelter/HEAD/Animal species and names reference.xlsx -------------------------------------------------------------------------------- /README.TXT: -------------------------------------------------------------------------------- 1 | 2 | ▄▄▄▄▄▄▄▄▄▄▄ ▄▄ ▄▄ ▄▄▄▄▄▄▄▄▄▄▄ ▄▄▄▄▄▄▄▄▄▄▄ ▄▄▄▄▄▄▄▄▄▄▄ ▄▄▄▄▄▄▄▄▄▄▄ ▄▄▄▄▄▄▄▄▄▄▄ ▄▄ ▄ ▄▄▄▄▄▄▄▄▄▄▄ ▄ 3 | ▐░░░░░░░░░░░▌▐░░▌ ▐░░▌▐░░░░░░░░░░░▌▐░░░░░░░░░░░▌▐░░░░░░░░░░░▌▐░░░░░░░░░░░▌▐░░░░░░░░░░░▌▐░░▌ ▐░▌▐░░░░░░░░░░░▌▐░▌ 4 | ▀▀▀▀█░█▀▀▀▀ ▐░▌░▌ ▐░▐░▌▐░█▀▀▀▀▀▀▀█░▌▐░█▀▀▀▀▀▀▀█░▌▐░█▀▀▀▀▀▀▀█░▌ ▀▀▀▀█░█▀▀▀▀ ▐░█▀▀▀▀▀▀▀█░▌▐░▌░▌ ▐░▌ ▀▀▀▀█░█▀▀▀▀ ▐░▌ 5 | ▐░▌ ▐░▌▐░▌ ▐░▌▐░▌▐░▌ ▐░▌▐░▌ ▐░▌▐░▌ ▐░▌ ▐░▌ ▐░▌ ▐░▌▐░▌▐░▌ ▐░▌ ▐░▌ ▐░▌ 6 | ▐░▌ ▐░▌ ▐░▐░▌ ▐░▌▐░█▄▄▄▄▄▄▄█░▌▐░▌ ▐░▌▐░█▄▄▄▄▄▄▄█░▌ ▐░▌ ▐░█▄▄▄▄▄▄▄█░▌▐░▌ ▐░▌ ▐░▌ ▐░▌ ▐░▌ 7 | ▐░▌ ▐░▌ ▐░▌ ▐░▌▐░░░░░░░░░░░▌▐░▌ ▐░▌▐░░░░░░░░░░░▌ ▐░▌ ▐░░░░░░░░░░░▌▐░▌ ▐░▌ ▐░▌ ▐░▌ ▐░▌ 8 | ▐░▌ ▐░▌ ▀ ▐░▌▐░█▀▀▀▀▀▀▀▀▀ ▐░▌ ▐░▌▐░█▀▀▀▀█░█▀▀ ▐░▌ ▐░█▀▀▀▀▀▀▀█░▌▐░▌ ▐░▌ ▐░▌ ▐░▌ ▐░▌ 9 | ▐░▌ ▐░▌ ▐░▌▐░▌ ▐░▌ ▐░▌▐░▌ ▐░▌ ▐░▌ ▐░▌ ▐░▌▐░▌ ▐░▌▐░▌ ▐░▌ ▀ 10 | ▄▄▄▄█░█▄▄▄▄ ▐░▌ ▐░▌▐░▌ ▐░█▄▄▄▄▄▄▄█░▌▐░▌ ▐░▌ ▐░▌ ▐░▌ ▐░▌▐░▌ ▐░▐░▌ ▐░▌ ▄ 11 | ▐░░░░░░░░░░░▌▐░▌ ▐░▌▐░▌ ▐░░░░░░░░░░░▌▐░▌ ▐░▌ ▐░▌ ▐░▌ ▐░▌▐░▌ ▐░░▌ ▐░▌ ▐░▌ 12 | ▀▀▀▀▀▀▀▀▀▀▀ ▀ ▀ ▀ ▀▀▀▀▀▀▀▀▀▀▀ ▀ ▀ ▀ ▀ ▀ ▀ ▀▀ ▀ ▀ 13 | 14 |                                                           15 | ------------------------------------------------------------------------------ 16 | This repository hosts the generic scripts for creating the Animal Shelter demo database used for my LinkedIn Learning advanced SQL courses. 17 | 18 | @@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@ 19 | @@ IMPORTANT - Each course uses its own subset of data and tables. @@ 20 | @@ If you are looking to practice and solve the course exercises, use these instead: @@ 21 | @@ 1. Query Processing - https://github.com/ami-levin/LinkedIn/tree/master/Query%20Processing/Demo%20Database @@ 22 | @@ 2. Window Functions - https://github.com/ami-levin/LinkedIn/tree/master/Window%20Functions/Demo%20Database @@ 23 | @@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@ 24 | 25 | This repository uses random generation of data with configurable parameters. 26 | It includes comments explaining my choices and some future options. 27 | 28 | Feel free to contribute, comment and use for your own purposes. 29 | If used for commercial purposes, please attribute using a link to this repository. 30 | -------------------------------------------------------------------------------- /02 - Create animal shelter schema and data.sql: -------------------------------------------------------------------------------- 1 | /* 2 | @@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@ 3 | @@ IMPORTANT - Each of my courses uses its own subset of the data and tables from this projcet. @@ 4 | @@ If you are looking for the practice demo database I use in my courses, follow these links: @@ 5 | @@ 1. Query Processing - https://github.com/ami-levin/LinkedIn/tree/master/Query%20Processing/Demo%20Database @@ 6 | @@ 2. Window Functions - https://github.com/ami-levin/LinkedIn/tree/master/Window%20Functions/Demo%20Database @@ 7 | @@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@ 8 | */ 9 | 10 | -- Animal shelter tables and data 11 | 12 | USE Animal_Shelter; 13 | GO 14 | 15 | -- Variable assignment 16 | DECLARE @Shelter_Open DATE = '20160101'; -- Shelter open day 17 | DECLARE @Last_Data_Day DATE = '20191231'; -- Last day of data 18 | DECLARE @Shelter_State VARCHAR(20) = 'California'; -- Shelter state 19 | DECLARE @Shelter_County VARCHAR(20) = 'Los Angeles';-- Shelter county - cities and addresses will be limited to the same county 20 | DECLARE @Max_Zip_Code CHAR(5) = '91000'; -- Further limit persons to zip areas below this number 21 | DECLARE @Max_Street_Number INT = 1000; -- Maximal number used to generate street address 22 | DECLARE @Min_Person_Age INT = 18; -- Minimum age of person as of shelter open 23 | DECLARE @Max_Person_Age INT = 70; -- Maximum age of person as of shelter open 24 | DECLARE @Num_Persons INT = 120; -- Number of persons 25 | DECLARE @Num_Veterinarians INT = 2; -- Number of staff vets 26 | DECLARE @Num_Assistants INT = 4; -- Number of staff assistants 27 | DECLARE @Num_receptionists INT = 2; -- Number of staff receptionists 28 | DECLARE @Num_Managers INT = 1; -- Number of managers 29 | DECLARE @Num_Dogs INT = 60; -- Number of dogs in shelter 30 | DECLARE @Num_Cats INT = 30; -- Number of cats in shelter 31 | DECLARE @Num_Rabbits INT = 10; -- Number of rabbits in shelter 32 | DECLARE @Num_Adoptions INT = 70; -- Number of total adoptions 33 | DECLARE @Min_Animal_Age_D INT = 1; -- Minimal age in days as of admission 34 | DECLARE @Max_Animal_Age_D INT = 18 * 12 * 30; -- Maximal age in days as of admission 35 | DECLARE @Min_Adoption_Fee INT = 50; -- Minimal adoption fee 36 | DECLARE @Max_Adoption_fee INT = 100; -- Maximal adoption fee 37 | DECLARE @Percent_Non_Breed INT = 75; -- Percent of non breed animals 38 | 39 | BEGIN TRANSACTION; -- easy rollback 40 | 41 | -- Operational data 42 | -- Persons 43 | CREATE TABLE Persons 44 | ( 45 | Email VARCHAR(100) NOT NULL 46 | PRIMARY KEY, 47 | First_Name VARCHAR(15) NOT NULL, 48 | Last_Name VARCHAR(15) NOT NULL, 49 | Birth_Date DATE NULL, 50 | Address VARCHAR(100) NOT NULL, 51 | State VARCHAR(20) NOT NULL, 52 | City VARCHAR(30) NOT NULL, 53 | Zip_Code CHAR(5) NOT NULL, 54 | ); 55 | 56 | WITH All_Possible_Names 57 | AS 58 | ( 59 | SELECT CASE Genders.Gender 60 | WHEN 'M' THEN CPN.Male 61 | ELSE CPN.Female 62 | END AS First_Name, 63 | CPN1.Surname AS Last_Name 64 | FROM Reference.Common_Person_Names AS CPN 65 | CROSS JOIN 66 | Reference.Common_Person_Names AS CPN1 67 | CROSS JOIN 68 | (VALUES ('F'), ('M')) AS Genders(Gender) 69 | ) 70 | INSERT INTO Persons (Email, First_Name, Last_Name, Birth_Date, Address, State, City, Zip_Code) 71 | SELECT LOWER(Random_Names.First_Name) + '.' + LOWER(Random_Names.Last_name) + '@' 72 | + CASE dbo.Random(1, 6) 73 | WHEN 1 THEN 'gmail' 74 | WHEN 2 THEN 'gmail' 75 | -- Gmail is more popular than other mail providers 76 | WHEN 3 THEN 'hotmail' 77 | WHEN 4 THEN 'yahoo' 78 | WHEN 5 THEN 'outlook' 79 | ELSE 'icloud' 80 | END + '.com' AS Email, 81 | Random_Names.First_Name, 82 | Random_Names.Last_Name, 83 | CASE 84 | WHEN dbo.Random(1,10) > 1 -- 10% did not provide birth date 85 | THEN 86 | DATEADD(DAY, dbo.Random(0, 365), DATEADD(YEAR, -dbo.Random(@Min_Person_Age, @Max_Person_Age), @Shelter_Open)) 87 | ELSE NULL 88 | END AS Birth_Date, 89 | Addresses.Address, 90 | @Shelter_State, 91 | Cities.City, 92 | Cities.Zip_Code 93 | FROM ( 94 | SELECT APN.First_Name, 95 | APN.Last_Name 96 | FROM All_Possible_Names AS APN 97 | ORDER BY NEWID() 98 | OFFSET 0 ROWS FETCH NEXT @Num_Persons ROWS ONLY 99 | ) AS Random_Names 100 | CROSS APPLY 101 | ( 102 | SELECT CZC.City, 103 | CZC.Zip_Code 104 | FROM Reference.City_Zip_Codes AS CZC 105 | INNER JOIN 106 | Reference.Cities AS C 107 | ON C.State = CZC.State 108 | AND 109 | C.City = CZC.City 110 | WHERE C.State = @Shelter_State 111 | AND 112 | C.County = @Shelter_County 113 | AND 114 | (CZC.Zip_Code < @Max_Zip_Code OR @Max_Zip_Code IS NULL) 115 | AND 116 | Random_Names.First_Name IS NOT NULL -- Force per row execution 117 | ORDER BY NEWID() 118 | OFFSET 0 ROWS FETCH NEXT 1 ROW ONLY 119 | ) AS Cities(City, Zip_Code) 120 | CROSS APPLY 121 | ( 122 | SELECT CAST(dbo.Random(1, @Max_Street_Number) AS VARCHAR(4)) + ' ' + CSN.Street 123 | FROM Reference.Common_Street_Names AS CSN 124 | WHERE Random_Names.First_Name IS NOT NULL -- Force per row execution 125 | ORDER BY NEWID() 126 | OFFSET 0 ROWS FETCH NEXT 1 ROW ONLY 127 | ) AS Addresses(Address); 128 | 129 | -- Staff roles 130 | CREATE TABLE Staff_Roles 131 | ( 132 | Role VARCHAR(20) NOT NULL PRIMARY KEY 133 | ); 134 | 135 | INSERT INTO Staff_Roles (Role) 136 | VALUES 137 | ('Receptionist'), ('Veterinarian'), ('Assistant'), ('Manager'), 138 | ('Janitor'); -- Latter will not be assigned, everyone helps clean up 139 | 140 | -- Staff 141 | CREATE TABLE Staff 142 | ( 143 | Email VARCHAR(100) NOT NULL 144 | PRIMARY KEY 145 | REFERENCES Persons (Email) 146 | ON UPDATE CASCADE 147 | ON DELETE NO ACTION, 148 | Hire_Date DATE NOT NULL 149 | ); 150 | 151 | INSERT INTO Staff (Email, Hire_Date) 152 | SELECT Email, 153 | DATEADD(DAY, dbo.Random(0, DATEDIFF(DAY, @Shelter_Open, @Last_Data_Day)), @Shelter_Open) 154 | FROM Persons 155 | ORDER BY NEWID() 156 | OFFSET 0 ROWS FETCH NEXT (@Num_receptionists + @Num_Managers + @Num_Assistants + @Num_Veterinarians) ROWS ONLY; 157 | 158 | -- Staff use 'animalshelter.com' domain addresses 159 | UPDATE Persons 160 | SET Email = LEFT(Email, CHARINDEX('@', Email)) + 'animalshelter.com' 161 | WHERE Email IN (SELECT Email FROM Staff); 162 | 163 | -- Staff roles 164 | CREATE TABLE Staff_Assignments 165 | ( 166 | Email VARCHAR(100) NOT NULL 167 | REFERENCES Staff (Email) 168 | ON UPDATE CASCADE 169 | ON DELETE NO ACTION, 170 | Role VARCHAR(20) NOT NULL 171 | REFERENCES Staff_Roles (Role) 172 | ON UPDATE CASCADE 173 | ON DELETE NO ACTION, 174 | Assigned DATE NOT NULL, 175 | PRIMARY KEY (Email, Role), 176 | INDEX NCIDX_FK_Staff_Assignments__Roles(Role) 177 | ); 178 | 179 | INSERT INTO Staff_Assignments (Email, Role, Assigned) 180 | SELECT S.Email, 181 | 'Veterinarian', 182 | S.Hire_Date 183 | FROM Staff AS S 184 | ORDER BY NEWID() 185 | OFFSET 0 ROWS FETCH NEXT @Num_Veterinarians ROWS ONLY; 186 | 187 | INSERT INTO Staff_Assignments (Email, Role, Assigned) 188 | SELECT S.Email, 189 | 'Assistant', 190 | S.Hire_Date 191 | FROM Staff AS S 192 | WHERE Email NOT IN ( SELECT Email FROM Staff_Assignments ) 193 | ORDER BY NEWID() 194 | OFFSET 0 ROWS FETCH NEXT (@Num_Assistants) ROWS ONLY; 195 | 196 | INSERT INTO Staff_Assignments (Email, Role, Assigned) 197 | SELECT S.Email, 198 | 'Receptionist', 199 | S.Hire_Date 200 | FROM Staff AS S 201 | WHERE Email NOT IN ( SELECT Email FROM Staff_Assignments ) 202 | ORDER BY NEWID() 203 | OFFSET 0 ROWS FETCH NEXT (@Num_receptionists) ROWS ONLY; 204 | 205 | INSERT INTO Staff_Assignments (Email, Role, Assigned) 206 | SELECT S.Email, 207 | 'Manager', 208 | S.Hire_Date 209 | FROM Staff AS S 210 | WHERE Email NOT IN ( SELECT Email FROM Staff_Assignments ) 211 | ORDER BY NEWID() 212 | OFFSET 0 ROWS FETCH NEXT @Num_Managers ROWS ONLY; 213 | 214 | -- 1 of each role on day 1 215 | WITH Staff_Rn 216 | AS 217 | ( 218 | SELECT *, 219 | ROW_NUMBER() OVER(PARTITION BY role ORDER BY Assigned ASC) AS Rn 220 | FROM Staff_Assignments 221 | ) 222 | UPDATE Staff_Rn 223 | SET Staff_Rn.Assigned = @Shelter_Open 224 | WHERE Rn = 1; 225 | 226 | -- update hire dates to match 227 | UPDATE Staff 228 | SET Hire_Date = (SELECT Assigned FROM Staff_Assignments AS SA WHERE SA.Email = Staff.Email); 229 | 230 | -- Animals 231 | CREATE TABLE Animals 232 | ( 233 | Name VARCHAR(20) NOT NULL, 234 | Species VARCHAR(10) NOT NULL, 235 | Primary_Color VARCHAR(10) NOT NULL 236 | REFERENCES Reference.Colors (Color), 237 | CONSTRAINT PK_Animals 238 | PRIMARY KEY (Name, Species), 239 | -- Business rule = unique identification of animal as name + species will do for a small sample set 240 | -- probably not enough for a real world scenario but depends on shelter naming conventions 241 | Implant_Chip_ID UNIQUEIDENTIFIER NOT NULL UNIQUE, 242 | -- This is the 'most natural' key, but it's unfamiliar and not very useful for human communication 243 | Breed VARCHAR(50) NULL, 244 | Gender CHAR(1) NOT NULL 245 | CHECK (Gender IN ( 'M', 'F' )), -- no need for gender fluidity in animals :-) 246 | Birth_Date DATE NOT NULL, 247 | Pattern VARCHAR(20) NOT NULL, 248 | CONSTRAINT FK_Animals__Patterns 249 | FOREIGN KEY (Species, Pattern) 250 | REFERENCES Reference.Patterns (Species, Pattern), 251 | Admission_Date DATE NOT NULL, 252 | CONSTRAINT FK_Animals__Breeds 253 | FOREIGN KEY (Species, Breed) 254 | REFERENCES Reference.Breeds (Species, Breed), 255 | INDEX NCIDX_FK_Animals__Patterns (Species, Pattern), 256 | INDEX NCIDX_FK_Animals__Breeds (Species, Breed), 257 | INDEX NCIDX_FK_Animals__Colors (Primary_Color) 258 | ); 259 | 260 | -- Dogs 261 | WITH Unpivoted_Names 262 | AS ( 263 | SELECT CAN.Species, 264 | Genders.Gender, 265 | CASE 266 | WHEN Genders.Gender = 'F' 267 | THEN CAN.Female 268 | ELSE CAN.Male 269 | END AS Name 270 | FROM Reference.Common_Animal_Names AS CAN 271 | CROSS JOIN 272 | (VALUES ('F'), ('M')) AS Genders (Gender) 273 | ), 274 | DeDuped_F_M_Names -- There are identical names for both M and F of the same species which we want to avoid since gender is not part of key 275 | AS 276 | ( 277 | SELECT UN.Species, 278 | CASE 279 | WHEN dbo.Random(1, 2) = 1 280 | THEN MAX(Gender) 281 | ELSE MIN(Gender) -- Pick arbitraty gender when duplicated 282 | END AS Gender, 283 | UN.Name 284 | FROM Unpivoted_Names AS UN 285 | GROUP BY UN.Species, UN.Name 286 | ) 287 | INSERT INTO Animals (Implant_Chip_ID, Species, Breed, Name, Gender, Birth_Date, Primary_Color, Pattern, Admission_Date) 288 | SELECT NEWID() AS Implant_Chip_ID, 289 | D.Species, 290 | B.Breed, -- Non breeds first 291 | D.Name, 292 | D.Gender, 293 | '20001010' AS Birth_Date, -- Place holder, will update later based on generated admission date 294 | C.Color, 295 | CP.Pattern, 296 | DATEADD(DAY, dbo.Random(0, DATEDIFF(DAY, @Shelter_Open, @Last_Data_Day)), @Shelter_Open) AS Admission_Date 297 | FROM DeDuped_F_M_Names AS D 298 | CROSS APPLY 299 | ( SELECT Color 300 | FROM Reference.Colors AS C 301 | ORDER BY NEWID(), D.Name 302 | OFFSET 0 ROWS FETCH NEXT 1 ROW ONLY 303 | ) AS C 304 | CROSS APPLY 305 | ( 306 | SELECT Pattern 307 | FROM Reference.Patterns AS P 308 | WHERE P.Species = D.Species 309 | ORDER BY NEWID(), C.Color 310 | OFFSET 0 ROWS FETCH NEXT 1 ROW ONLY 311 | ) AS CP 312 | CROSS APPLY 313 | ( 314 | SELECT Breed 315 | FROM Reference.Breeds AS B 316 | WHERE B.Species = D.Species 317 | ORDER BY NEWID(), C.Color 318 | OFFSET 0 ROWS FETCH NEXT 1 ROW ONLY 319 | ) AS B(Breed) 320 | WHERE D.Species = 'Dog' 321 | ORDER BY NEWID() 322 | OFFSET 0 ROWS FETCH NEXT (@Num_Dogs) ROWS ONLY; 323 | 324 | -- Cats 325 | WITH Unpivoted_Names 326 | AS ( 327 | SELECT CAN.Species, 328 | Genders.Gender, 329 | CASE 330 | WHEN Genders.Gender = 'F' 331 | THEN CAN.Female 332 | ELSE CAN.Male 333 | END AS Name 334 | FROM Reference.Common_Animal_Names AS CAN 335 | CROSS JOIN 336 | (VALUES ('F'), ('M')) AS Genders (Gender) 337 | ), 338 | DeDuped_F_M_Names -- There are identical names for both M and F of the same species-avoid since we don't have gender in key 339 | AS 340 | ( 341 | SELECT UN.Species, 342 | CASE 343 | WHEN dbo.Random(1, 2) = 1 344 | THEN MAX(Gender) 345 | ELSE MIN(Gender) -- Pick arbitraty gender when duplicated 346 | END AS Gender, 347 | UN.Name 348 | FROM Unpivoted_Names AS UN 349 | GROUP BY UN.Species, UN.Name 350 | ) 351 | INSERT INTO Animals (Implant_Chip_ID, Species, Breed, Name, Gender, Birth_Date, Primary_Color, Pattern, Admission_Date) 352 | SELECT NEWID() AS Implant_Chip_ID, 353 | D.Species, 354 | B.Breed, -- Non breeds first 355 | D.Name, 356 | D.Gender, 357 | '20001010' AS Birth_Date, -- Place holder, will update later based on generated admission date 358 | CASE WHEN B.Breed LIKE '%Blue%' THEN 'Gray' ELSE C.Color END, 359 | CP.Pattern, 360 | DATEADD(DAY, dbo.Random(0, DATEDIFF(DAY, @Shelter_Open, @Last_Data_Day)), @Shelter_Open) AS Admission_Date 361 | FROM DeDuped_F_M_Names AS D 362 | CROSS APPLY 363 | ( SELECT Color 364 | FROM Reference.Colors AS C 365 | ORDER BY NEWID(), D.Name 366 | OFFSET 0 ROWS FETCH NEXT 1 ROW ONLY 367 | ) AS C 368 | CROSS APPLY 369 | ( 370 | SELECT Pattern 371 | FROM Reference.Patterns AS P 372 | WHERE P.Species = D.Species 373 | ORDER BY NEWID(), C.Color, D.Name 374 | OFFSET 0 ROWS FETCH NEXT 1 ROW ONLY 375 | ) AS CP 376 | CROSS APPLY 377 | ( 378 | SELECT Breed 379 | FROM Reference.Breeds AS B 380 | WHERE B.Species = D.Species 381 | ORDER BY NEWID(), C.Color, D.Name, CP.Pattern 382 | OFFSET 0 ROWS FETCH NEXT 1 ROW ONLY 383 | ) AS B(Breed) 384 | WHERE D.Species = 'Cat' 385 | ORDER BY NEWID() 386 | OFFSET 0 ROWS FETCH NEXT (@Num_Cats) ROWS ONLY; 387 | 388 | -- Rabbits 389 | WITH Unpivoted_Names 390 | AS ( 391 | SELECT CAN.Species, 392 | Genders.Gender, 393 | CASE 394 | WHEN Genders.Gender = 'F' 395 | THEN CAN.Female 396 | ELSE CAN.Male 397 | END AS Name 398 | FROM Reference.Common_Animal_Names AS CAN 399 | CROSS JOIN 400 | (VALUES ('F'), ('M')) AS Genders (Gender) 401 | ), 402 | DeDuped_F_M_Names -- There are identical names for both M and F of the same species-avoid since we don't have gender in key 403 | AS 404 | ( 405 | SELECT UN.Species, 406 | CASE 407 | WHEN dbo.Random(1, 2) = 1 408 | THEN MAX(Gender) 409 | ELSE MIN(Gender) -- Pick arbitraty gender when duplicated 410 | END AS Gender, 411 | UN.Name 412 | FROM Unpivoted_Names AS UN 413 | GROUP BY UN.Species, UN.Name 414 | ) 415 | INSERT INTO Animals (Implant_Chip_ID, Species, Breed, Name, Gender, Birth_Date, Primary_Color, Pattern, Admission_Date) 416 | SELECT NEWID() AS Implant_Chip_ID, 417 | D.Species, 418 | B.Breed, -- Non breeds first 419 | D.Name, 420 | D.Gender, 421 | '20001010' AS Birth_Date, -- Place holder, will update later based on generated admission date 422 | C.Color, 423 | CP.Pattern, 424 | DATEADD(DAY, dbo.Random(0, DATEDIFF(DAY, @Shelter_Open, @Last_Data_Day)), @Shelter_Open) AS Admission_Date 425 | FROM DeDuped_F_M_Names AS D 426 | CROSS APPLY 427 | ( SELECT Color 428 | FROM Reference.Colors AS C 429 | ORDER BY NEWID(), D.Name 430 | OFFSET 0 ROWS FETCH NEXT 1 ROW ONLY 431 | ) AS C 432 | CROSS APPLY 433 | ( 434 | SELECT Pattern 435 | FROM Reference.Patterns AS P 436 | WHERE P.Species = D.Species 437 | ORDER BY NEWID(), C.Color 438 | OFFSET 0 ROWS FETCH NEXT 1 ROW ONLY 439 | ) AS CP 440 | CROSS APPLY 441 | ( 442 | SELECT Breed 443 | FROM Reference.Breeds AS B 444 | WHERE B.Species = D.Species 445 | ORDER BY NEWID(), C.Color 446 | OFFSET 0 ROWS FETCH NEXT 1 ROW ONLY 447 | ) AS B(Breed) 448 | WHERE D.Species = 'Rabbit' 449 | ORDER BY NEWID() 450 | OFFSET 0 ROWS FETCH NEXT (@Num_Rabbits) ROWS ONLY; 451 | 452 | -- Most animals are non breed 453 | UPDATE Animals 454 | SET Breed = CASE 455 | WHEN dbo.Random(1, 100) > @Percent_Non_Breed 456 | THEN Breed 457 | ELSE NULL 458 | END; 459 | 460 | -- Now update to 'real' birth dates based on generated admission date 461 | UPDATE Animals 462 | SET Birth_Date = DATEADD(DAY, -dbo.Random(@Min_Animal_Age_D, @Max_Animal_Age_D), Admission_Date); 463 | 464 | -- Adoptions 465 | CREATE TABLE Adoptions 466 | ( 467 | Name VARCHAR(20) NOT NULL, 468 | Species VARCHAR(10) NOT NULL, 469 | CONSTRAINT FK_Adoptions__Animals 470 | FOREIGN KEY (Name, Species) 471 | REFERENCES Animals (Name, Species) 472 | ON UPDATE CASCADE 473 | ON DELETE NO ACTION, 474 | Adopter_Email VARCHAR(100) NOT NULL 475 | REFERENCES Persons (Email) 476 | ON UPDATE CASCADE 477 | ON DELETE NO ACTION, 478 | PRIMARY KEY (Name, Species, Adopter_Email), 479 | -- An animal may be adopted only once by the same person (allows for future implementation of adoption returns) 480 | Adoption_Date DATE NOT NULL, 481 | Adoption_Fee SMALLINT NOT NULL CHECK (Adoption_Fee >= 0), 482 | INDEX NCIDX_FK_Adoptions__Persons (Adopter_Email), 483 | ); 484 | 485 | INSERT INTO Adoptions (Name, Species, Adopter_Email, Adoption_Date, Adoption_Fee) 486 | SELECT A.Name, 487 | A.Species, 488 | Adopter.Email, 489 | Adoption.Date, 490 | dbo.Random(@Min_Adoption_Fee, @Max_Adoption_fee) 491 | FROM Animals AS A 492 | CROSS APPLY 493 | ( 494 | SELECT C.Date 495 | FROM Reference.Calendar AS C 496 | WHERE C.Date > A.Admission_Date 497 | AND 498 | C.Date < @Last_Data_Day 499 | ORDER BY NEWID() 500 | OFFSET 0 ROWS FETCH NEXT 1 ROW ONLY 501 | ) AS Adoption(Date) 502 | CROSS APPLY 503 | ( 504 | SELECT Email 505 | FROM Persons 506 | WHERE Adoption.Date IS NOT NULL -- dummy reference to force row execution 507 | ORDER BY NEWID() 508 | OFFSET 0 ROWS FETCH NEXT 1 ROW ONLY 509 | ) AS Adopter 510 | ORDER BY NEWID() 511 | OFFSET 0 ROWS FETCH NEXT @Num_Adoptions ROWS ONLY; 512 | 513 | /* -- Future optional 514 | -- Animal routine checkups 515 | CREATE TABLE Routine_Checkups 516 | ( 517 | Name VARCHAR(20) NOT NULL, 518 | Species VARCHAR(10) NOT NULL, 519 | CONSTRAINT FK_Routine_Checkups__Animals 520 | FOREIGN KEY (Name, Species) 521 | REFERENCES Animals (Name, Species), 522 | Checkup_Time DATETIME2 NOT NULL, 523 | Temperature_F DECIMAL(4, 1) NOT NULL, 524 | Heart_Rate TINYINT NOT NULL, 525 | Respiration TINYINT NOT NULL, 526 | Weight_Lbs DECIMAL(4, 1) NOT NULL, 527 | Comments VARCHAR(500) NULL, 528 | Performed_By VARCHAR(100) NOT NULL 529 | REFERENCES Staff (Email) 530 | ON UPDATE CASCADE 531 | ON DELETE NO ACTION, 532 | PRIMARY KEY (Name, Species, Checkup_Time), 533 | INDEX NCIDX_FK_Routine_Checkups__Staff(Performed_By) 534 | ); 535 | 536 | INSERT INTO Routine_Checkups 537 | (Name, Species, Checkup_Time, Temperature_F, Heart_Rate, Respiration, Weight_Lbs, Comments, Performed_By) 538 | SELECT A.Name, 539 | A.Species, 540 | DATEADD(MINUTE, (7 * 60) + dbo.Random(0, (8 * 60)), CAST(C.Date AS DATETIME2)) AS Checkup_Time, 541 | ROUND( 542 | (SNR.Temperature_Low + ((SNR.Temperature_High - SNR.Temperature_Low) / 2.00)) -- Middle of range 543 | + ((dbo.Random(-10, 10) / 30.00) * (SNR.Temperature_High - SNR.Temperature_Low)) -- +/- 30% around the middle of the range 544 | + CASE 545 | WHEN dbo.Random(1, 100) < 100 -- 1 in 100 rows give abnormal reading 546 | THEN 547 | 0 548 | ELSE 549 | (dbo.Random(-10, 10) / 30.00) * (SNR.Temperature_High - SNR.Temperature_Low) -- by +/- 1/3 of range 550 | END, 551 | 1 552 | ) AS Temperature, 553 | ROUND( 554 | (SNR.Heart_Rate_Low + ((SNR.Heart_Rate_high - SNR.Heart_Rate_Low) / 2.00)) -- Middle of range 555 | + ((dbo.Random(-10, 10) / 30.00) * (SNR.Heart_Rate_high - SNR.Heart_Rate_Low)) -- +/- 30% around the middle of the range 556 | + CASE 557 | WHEN dbo.Random(1, 100) < 100 -- 1 in 100 rows give abnormal reading 558 | THEN 559 | 0 560 | ELSE 561 | (dbo.Random(-10, 10) / 30.00) * (SNR.Heart_Rate_high - SNR.Heart_Rate_Low) -- by +/- 1/3 of range 562 | END, 563 | 0 564 | ) AS Heart_Rate, 565 | ROUND( 566 | (SNR.Respiratory_Rate_Low + ((SNR.Respiratory_Rate_High - SNR.Respiratory_Rate_Low) / 2.00)) -- Middle of range 567 | + ((dbo.Random(-10, 10) / 30.00) * (SNR.Respiratory_Rate_High - SNR.Respiratory_Rate_Low)) -- +/- 30% around the middle of the range 568 | + CASE 569 | WHEN dbo.Random(1, 100) < 100 -- 1 in 100 rows give abnormal reading 570 | THEN 571 | 0 572 | ELSE 573 | (dbo.Random(-10, 10) / 30.00) * (SNR.Respiratory_Rate_High - SNR.Respiratory_Rate_Low) -- by +/- 1/3 of range 574 | END, 575 | 0 576 | ) AS Respistory_Rate, 577 | ROUND( 578 | CASE A.Species 579 | WHEN 'Cat' THEN 580 | 6.00 + ((ABS(CHECKSUM(A.Breed)) % 24) / 2) -- consistent base weight / breed 581 | + ((CASE WHEN dbo.Random(1, 10) < 10 THEN 0 ELSE 1 END) * (dbo.Random(-10, 10) / 20.00)) -- cats (6 - 17 lbs) +/- 0.5 lbs 1 in 10 582 | WHEN 'Dog' THEN 583 | 15.00 + ((ABS(CHECKSUM(A.Breed)) % 72) / 2) 584 | + ((CASE WHEN dbo.Random(1, 10) < 10 THEN 0 ELSE 1 END) * (dbo.Random(-15, 15) / 10.00)) -- dogs (15 - 50 lbs) + / 1.5 lbs 1 in 10 585 | ELSE 586 | 2.00 + (ABS(CHECKSUM(A.Breed) % 21)) / 3 587 | + ((CASE WHEN dbo.Random(1, 20) < 20 THEN 0 ELSE 1 END) * (dbo.Random(-10, 10) / 50.00)) -- rabbits (2 - 8 lbs) +/ 0.2 lbs 1 in 20 588 | END, 589 | 1 590 | ) AS Weight, 591 | NULL AS Comments, 592 | Staff.Email 593 | FROM ( 594 | Animals AS A 595 | LEFT OUTER JOIN 596 | Adoptions AS AD 597 | ON A.Name = AD.Name 598 | AND 599 | A.Species = AD.Species 600 | ) 601 | INNER JOIN 602 | Reference.Species_Vital_Signs_Ranges AS SNR 603 | ON A.Species = SNR.Species 604 | CROSS JOIN 605 | Reference.Calendar AS C 606 | CROSS APPLY ( SELECT Email 607 | FROM Staff 608 | WHERE C.Date >= Staff.Hire_Date 609 | AND 610 | Email IN (SELECT Email FROM Staff_Assignments WHERE Role IN ('Veterinarian', 'Assistant')) 611 | -- Dirty shortcut but Emails are unique... 612 | ORDER BY NEWID() 613 | OFFSET 0 ROWS FETCH NEXT 1 ROW ONLY 614 | ) AS Staff 615 | WHERE C.Date BETWEEN @Shelter_Open AND @Last_Data_Day 616 | AND 617 | C.Weekday BETWEEN 2 AND 6 618 | AND 619 | C.US_Federal_Holiday IS NULL 620 | AND 621 | (ABS(CHECKSUM(A.Name + A.Species)) % 5) + 2 = C.Weekday -- every animal checked weekly 622 | AND 623 | C.Date >= A.Admission_Date -- only post admission 624 | AND 625 | C.Date <= ISNULL(AD.Adoption_Date, @Last_Data_Day) -- only pre-adoption 626 | AND 627 | ABS(CHECKSUM(A.Name + A.Species + CAST(C.Date AS VARCHAR(20))) % 100) > 74; -- only 1/4 of all possible combinations 628 | */ 629 | 630 | CREATE TABLE Vaccinations 631 | ( 632 | Name VARCHAR(20) NOT NULL, 633 | Species VARCHAR(10) NOT NULL, 634 | CONSTRAINT FK_Vaccinations__Animals 635 | FOREIGN KEY (Name, Species) 636 | REFERENCES Animals (Name, Species), 637 | Vaccination_Time DATETIME2 NOT NULL, 638 | Vaccine VARCHAR(50) NOT NULL, 639 | CONSTRAINT FK_Vaccinations__Species_Vaccines 640 | FOREIGN KEY (Species, Vaccine) 641 | REFERENCES Reference.Species_Vaccines (Species, Vaccine) 642 | ON UPDATE CASCADE 643 | ON DELETE NO ACTION, 644 | Batch VARCHAR(20) NOT NULL, 645 | Comments VARCHAR(500) NULL, 646 | Email VARCHAR(100) NOT NULL 647 | REFERENCES Staff (Email) 648 | ON UPDATE CASCADE 649 | ON DELETE NO ACTION, 650 | PRIMARY KEY (Name, Species, Vaccine, Vaccination_Time), 651 | INDEX NCIDX_FK_Vaccinations__Vaccines(Species, Vaccine), 652 | INDEX NCIDX_FK_Vaccinations__Staff(Email) 653 | ); 654 | 655 | INSERT INTO Vaccinations (Name, Species, Vaccination_Time, Vaccine, Batch, Comments, Email) 656 | SELECT A.Name, 657 | A.Species, 658 | DATEADD(MINUTE, (7 * 60) + dbo.Random(0, (8 * 60)), CAST(C.Date AS DATETIME2)) AS Vaccination_Time, 659 | V.Vaccine, 660 | CHAR(dbo.Random(ASCII('A'), ASCII('Z'))) + '-' + CAST(dbo.Random(500000000, 99000000) AS CHAR(9)), 661 | NULL, 662 | Staff.Email 663 | FROM ( Animals AS A 664 | LEFT OUTER JOIN 665 | Adoptions AS AD 666 | ON A.Name = AD.Name 667 | AND 668 | A.Species = AD.Species 669 | ) 670 | INNER JOIN 671 | Reference.Species_Vaccines AS V 672 | ON V.Species = A.Species 673 | CROSS JOIN 674 | Reference.Calendar AS C 675 | CROSS APPLY 676 | ( 677 | SELECT Email 678 | FROM Staff 679 | WHERE C.Date >= Staff.Hire_Date -- After hire date 680 | AND 681 | A.name IS NOT NULL AND V.Vaccine IS NOT NULL 682 | AND 683 | Email IN (SELECT Email FROM Staff_Assignments WHERE Role IN ('Veterinarian', 'Assistant')) 684 | -- Dirty shortcut but Emails are unique... 685 | ORDER BY NEWID() OFFSET 0 ROWS FETCH NEXT 1 ROW ONLY 686 | ) AS Staff 687 | WHERE V.Species = A.Species 688 | AND 689 | C.Date BETWEEN @Shelter_Open AND @Last_Data_Day 690 | AND 691 | (ABS(CHECKSUM(A.Species + A.Name)) % 365) + 1 = C.Day_of_Year -- every animal vaccinated annualy 692 | AND 693 | C.Weekday BETWEEN 2 AND 6 -- on weekdays only 694 | AND 695 | C.US_Federal_Holiday IS NULL -- not on holidays 696 | AND 697 | C.Date >= A.Admission_Date -- only post admission 698 | AND 699 | C.Date <= ISNULL(AD.Adoption_Date, @Last_Data_Day) -- only pre-adoption 700 | AND 701 | 1 = CASE 702 | WHEN DATEDIFF(WEEK, A.Birth_Date, C.Date) NOT BETWEEN 14 AND 16 -- Parvo between 14 and 16 weeks only 703 | AND V.Vaccine = 'Parvovirus' THEN 704 | 0 705 | ELSE 706 | 1 707 | END 708 | AND 709 | ABS(CHECKSUM(A.Name + V.Vaccine + CAST(C.Date AS VARCHAR(20))) % 100) > 66 -- only 1/3 of all possible combinations 710 | 711 | ----------------------- 712 | -- Sanity check data -- 713 | ----------------------- 714 | 715 | SELECT 'Persons' AS Table_Name, 716 | * 717 | FROM Persons 718 | ORDER BY Email OFFSET 0 ROWS FETCH NEXT 100 ROWS ONLY; 719 | 720 | SELECT 'Staff' AS Table_Name, 721 | * 722 | FROM Staff 723 | ORDER BY Email OFFSET 0 ROWS FETCH NEXT 100 ROWS ONLY; 724 | 725 | SELECT 'Staff_Assignments' AS Table_Name, 726 | * 727 | FROM Staff_Assignments 728 | ORDER BY Email OFFSET 0 ROWS FETCH NEXT 100 ROWS ONLY; 729 | 730 | SELECT 'Animals' AS Table_Name, 731 | * 732 | FROM Animals 733 | ORDER BY Species, 734 | Breed, 735 | Name OFFSET 0 ROWS FETCH NEXT 100 ROWS ONLY; 736 | 737 | SELECT 'Adoptions' AS Table_Name, 738 | * 739 | FROM Adoptions 740 | ORDER BY Adoption_Date OFFSET 0 ROWS FETCH NEXT 100 ROWS ONLY; 741 | 742 | --SELECT 'Routine_Checkups' AS Table_Name, 743 | -- * 744 | --FROM Routine_Checkups 745 | --ORDER BY Checkup_Time OFFSET 0 ROWS FETCH NEXT 100 ROWS ONLY; 746 | 747 | SELECT 'Vaccinations' AS Table_Name, 748 | * 749 | FROM Vaccinations 750 | ORDER BY Vaccination_Time OFFSET 0 ROWS FETCH NEXT 100 ROWS ONLY; 751 | 752 | SELECT COUNT(*) AS Num_Persons, 753 | MIN(Birth_Date) AS Min_Birth_Date, 754 | MAX(Birth_Date) AS Max_Birth_Date 755 | FROM Persons; 756 | 757 | SELECT COUNT(*) AS Num_Staff, 758 | MIN(Hire_Date) AS Min_Hire_Date, 759 | MAX(Hire_Date) AS Max_Hire_Date 760 | FROM Staff; 761 | 762 | SELECT COUNT(*) AS Num_Assignments, 763 | MIN(Assigned) AS Min_A, 764 | MAX(Assigned) AS Max_A 765 | FROM Staff_Assignments; 766 | 767 | SELECT Species, 768 | Breed, 769 | COUNT(*) AS Num_Animals 770 | FROM Animals 771 | GROUP BY GROUPING SETS (Species), (Breed) 772 | ORDER BY Species, 773 | Breed, 774 | Num_Animals DESC; 775 | 776 | --SELECT COUNT(*) AS Total_Routine_Checkups 777 | --FROM Routine_Checkups; 778 | 779 | SELECT COUNT(*) AS Total_Vaccinations 780 | FROM Vaccinations AS V 781 | 782 | SELECT COUNT(*) AS Num_Adoptions, 783 | MIN(Adoption_Date) AS Min_Adoption_Date, 784 | MAX(Adoption_Date) AS Max_Adoption_Date 785 | FROM Adoptions; 786 | 787 | SELECT Adopter_Email, 788 | COUNT(*) AS Num_Adopted 789 | FROM Adoptions 790 | GROUP BY Adopter_Email; 791 | 792 | --SELECT A.Species, 793 | -- COUNT(*) AS Num_Rows, 794 | -- MIN(RC.Temperature_F) AS Min_Temp, 795 | -- MAX(RC.Temperature_F) AS Max_Temp, 796 | -- AVG(RC.Temperature_F) AS Avg_Temp, 797 | -- MIN(RC.Heart_Rate) AS Min_Heart, 798 | -- MAX(RC.Heart_Rate) AS Max_Heart, 799 | -- AVG(RC.Heart_Rate) AS Avg_Heart, 800 | -- MIN(RC.Respiration) AS Min_Resp, 801 | -- MAX(RC.Respiration) AS Max_Resp, 802 | -- AVG(RC.Respiration) AS Avg_Resp, 803 | -- MIN(RC.Weight_Lbs) AS Min_Weight, 804 | -- MAX(RC.Weight_Lbs) AS Max_Weight, 805 | -- AVG(RC.Weight_Lbs) AS Avg_Weight 806 | --FROM Routine_Checkups AS RC 807 | -- INNER JOIN 808 | -- Animals AS A 809 | -- ON A.Name = RC.Name 810 | -- AND 811 | -- A.Species = RC.Species 812 | --GROUP BY A.Species; 813 | 814 | COMMIT TRANSACTION; 815 | -------------------------------------------------------------------------------- /01 - Create database and reference data.sql: -------------------------------------------------------------------------------- 1 | /* 2 | @@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@ 3 | @@ IMPORTANT - Each of my courses uses its own subset of the data and tables from this projcet. @@ 4 | @@ If you are looking for the practice demo database I use in my courses, follow these links: @@ 5 | @@ 1. Query Processing - https://github.com/ami-levin/LinkedIn/tree/master/Query%20Processing/Demo%20Database @@ 6 | @@ 2. Window Functions - https://github.com/ami-levin/LinkedIn/tree/master/Window%20Functions/Demo%20Database @@ 7 | @@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@ 8 | */ 9 | 10 | -- Create database and reference data tables 11 | -- SQL Server 12 | 13 | USE master; 14 | GO 15 | 16 | IF DB_ID('Animal_Shelter') IS NOT NULL 17 | BEGIN 18 | ALTER DATABASE Animal_Shelter SET SINGLE_USER WITH ROLLBACK IMMEDIATE; 19 | DROP DATABASE Animal_Shelter; 20 | END; 21 | GO 22 | 23 | CREATE DATABASE Animal_Shelter; 24 | GO 25 | 26 | USE Animal_Shelter; 27 | GO 28 | 29 | CREATE SCHEMA Reference; 30 | GO 31 | 32 | -- Random convenience function 33 | CREATE OR ALTER VIEW dbo.V_Random 34 | AS 35 | SELECT RAND() AS Random; 36 | GO 37 | 38 | CREATE OR ALTER FUNCTION dbo.Random (@low INT, @high INT) 39 | RETURNS INT 40 | AS 41 | BEGIN 42 | RETURN 43 | ( 44 | SELECT CASE 45 | WHEN @low >= 0 THEN 46 | @low + (Random * (@high - @low + 1)) 47 | ELSE 48 | @low + (Random * (@high - @low + 2)) - 1 -- correct for rounding 49 | END 50 | FROM V_Random 51 | ); 52 | END; 53 | GO 54 | 55 | -- Variable declaration 56 | DECLARE @Min_Population INT = 10000; -- Min population for a city to be included 57 | DECLARE @Min_Date_Calendar DATE = '19900101'; -- Calendar start date 58 | DECLARE @Max_Date_Calendar DATE = '20500101'; -- Calendar end date 59 | 60 | -- Common person names in the US 61 | -- Source https://names.mongabay.com/ (was all caps in source) 62 | CREATE TABLE Reference.Common_Person_Names 63 | ( 64 | [Rank] TINYINT NOT NULL PRIMARY KEY, 65 | Surname VARCHAR(20) NOT NULL UNIQUE, 66 | Male VARCHAR(20) NOT NULL UNIQUE, 67 | Female VARCHAR(20) NOT NULL UNIQUE 68 | ); 69 | 70 | INSERT INTO Reference.Common_Person_Names ([Rank], Surname, Male, Female) 71 | SELECT n.RANK, 72 | LEFT(n.Surname, 1) + RIGHT(LOWER(n.Surname), LEN(n.Surname) - 1) AS Surname, 73 | LEFT(n.Male, 1) + RIGHT(LOWER(n.Male), LEN(n.Male) - 1) AS Male, 74 | LEFT(n.Female, 1) + RIGHT(LOWER(n.Female), LEN(n.Female) - 1) AS Female 75 | FROM 76 | ( 77 | VALUES (1, 'SMITH', 'MARY', 'JAMES'), (2, 'JOHNSON', 'PATRICIA', 'JOHN'), (3, 'WILLIAMS', 'LINDA', 'ROBERT'), (4, 'BROWN', 'BARBARA', 'MICHAEL'), 78 | (5, 'JONES', 'ELIZABETH', 'WILLIAM'), (6, 'GARCIA', 'JENNIFER', 'DAVID'), (7, 'MILLER', 'MARIA', 'RICHARD'), (8, 'DAVIS', 'SUSAN', 'CHARLES'), 79 | (9, 'RODRIGUEZ', 'MARGARET', 'JOSEPH'), (10, 'MARTINEZ', 'DOROTHY', 'THOMAS'), (11, 'HERNANDEZ', 'LISA', 'CHRISTOPHER'), (12, 'LOPEZ', 'NANCY', 'DANIEL'), 80 | (13, 'GONZALEZ', 'KAREN', 'PAUL'), (14, 'WILSON', 'BETTY', 'MARK'), (15, 'ANDERSON', 'HELEN', 'DONALD'), (16, 'THOMAS', 'SANDRA', 'GEORGE'), 81 | (17, 'TAYLOR', 'DONNA', 'KENNETH'), (18, 'MOORE', 'CAROL', 'STEVEN'), (19, 'JACKSON', 'RUTH', 'EDWARD'), (20, 'MARTIN', 'SHARON', 'BRIAN'), 82 | (21, 'LEE', 'MICHELLE', 'RONALD'), (22, 'PEREZ', 'LAURA', 'ANTHONY'), (23, 'THOMPSON', 'SARAH', 'KEVIN'), (24, 'WHITE', 'KIMBERLY', 'JASON'), 83 | (25, 'HARRIS', 'DEBORAH', 'MATTHEW'), (26, 'SANCHEZ', 'JESSICA', 'GARY'), (27, 'CLARK', 'SHIRLEY', 'TIMOTHY'), (28, 'RAMIREZ', 'CYNTHIA', 'JOSE'), 84 | (29, 'LEWIS', 'ANGELA', 'LARRY'), (30, 'ROBINSON', 'MELISSA', 'JEFFREY'), (31, 'WALKER', 'BRENDA', 'FRANK'), (32, 'YOUNG', 'AMY', 'SCOTT'), 85 | (33, 'ALLEN', 'ANNA', 'ERIC'), (34, 'KING', 'REBECCA', 'STEPHEN'), (35, 'WRIGHT', 'VIRGINIA', 'ANDREW'), (36, 'SCOTT', 'KATHLEEN', 'RAYMOND'), 86 | (37, 'TORRES', 'PAMELA', 'GREGORY'), (38, 'NGUYEN', 'MARTHA', 'JOSHUA'), (39, 'HILL', 'DEBRA', 'JERRY'), (40, 'FLORES', 'AMANDA', 'DENNIS'), 87 | (41, 'GREEN', 'STEPHANIE', 'WALTER'), (42, 'ADAMS', 'CAROLYN', 'PATRICK'), (43, 'NELSON', 'CHRISTINE', 'PETER'), (44, 'BAKER', 'MARIE', 'HAROLD'), 88 | (45, 'HALL', 'JANET', 'DOUGLAS'), (46, 'RIVERA', 'CATHERINE', 'HENRY'), (47, 'CAMPBELL', 'FRANCES', 'CARL'), (48, 'MITCHELL', 'ANN', 'ARTHUR'), 89 | (49, 'CARTER', 'JOYCE', 'RYAN'), (50, 'ROBERTS', 'DIANE', 'ROGER'), (51, 'GOMEZ', 'ALICE', 'JOE'), (52, 'PHILLIPS', 'JULIE', 'JUAN'), 90 | (53, 'EVANS', 'HEATHER', 'JACK'), (54, 'TURNER', 'TERESA', 'ALBERT'), (55, 'DIAZ', 'DORIS', 'JONATHAN'), (56, 'PARKER', 'GLORIA', 'JUSTIN'), 91 | (57, 'CRUZ', 'EVELYN', 'TERRY'), (58, 'EDWARDS', 'JEAN', 'GERALD'), (59, 'COLLINS', 'CHERYL', 'KEITH'), (60, 'REYES', 'MILDRED', 'SAMUEL'), 92 | (61, 'STEWART', 'KATHERINE', 'WILLIE'), (62, 'MORRIS', 'JOAN', 'RALPH'), (63, 'MORALES', 'ASHLEY', 'LAWRENCE'), (64, 'MURPHY', 'JUDITH', 'NICHOLAS'), 93 | (65, 'COOK', 'ROSE', 'ROY'), (66, 'ROGERS', 'JANICE', 'BENJAMIN'), (67, 'GUTIERREZ', 'KELLY', 'BRUCE'), (68, 'ORTIZ', 'NICOLE', 'BRANDON'), 94 | (69, 'MORGAN', 'JUDY', 'ADAM'), (70, 'COOPER', 'CHRISTINA', 'HARRY'), (71, 'PETERSON', 'KATHY', 'FRED'), (72, 'BAILEY', 'THERESA', 'WAYNE'), 95 | (73, 'REED', 'BEVERLY', 'BILLY'), (74, 'KELLY', 'DENISE', 'STEVE'), (75, 'HOWARD', 'TAMMY', 'LOUIS'), (76, 'RAMOS', 'IRENE', 'JEREMY'), 96 | (77, 'KIM', 'JANE', 'AARON'), (78, 'COX', 'LORI', 'RANDY'), (79, 'WARD', 'RACHEL', 'HOWARD'), (80, 'RICHARDSON', 'MARILYN', 'EUGENE'), 97 | (81, 'WATSON', 'ANDREA', 'CARLOS'), (82, 'BROOKS', 'KATHRYN', 'RUSSELL'), (83, 'CHAVEZ', 'LOUISE', 'BOBBY'), (84, 'WOOD', 'SARA', 'VICTOR'), 98 | (85, 'JAMES', 'ANNE', 'MARTIN'), (86, 'BENNETT', 'JACQUELINE', 'ERNEST'), (87, 'GRAY', 'WANDA', 'PHILLIP'), (88, 'MENDOZA', 'BONNIE', 'TODD'), 99 | (89, 'RUIZ', 'JULIA', 'JESSE'), (90, 'HUGHES', 'RUBY', 'CRAIG'), (91, 'PRICE', 'LOIS', 'ALAN'), (92, 'ALVAREZ', 'TINA', 'SHAWN'), 100 | (93, 'CASTILLO', 'PHYLLIS', 'CLARENCE'), (94, 'SANDERS', 'NORMA', 'SEAN'), (95, 'PATEL', 'PAULA', 'PHILIP'), (96, 'MYERS', 'DIANA', 'CHRIS'), 101 | (97, 'LONG', 'ANNIE', 'JOHNNY'), (98, 'ROSS', 'LILLIAN', 'EARL'), (99, 'FOSTER', 'EMILY', 'JIMMY'), (100, 'JIMENEZ', 'ROBIN', 'ANTONIO') 102 | ) AS n ([RANK], Surname, Female, Male); 103 | 104 | -- Species 105 | CREATE TABLE Reference.Species 106 | ( 107 | Species VARCHAR(10) NOT NULL PRIMARY KEY 108 | ); 109 | 110 | -- Populate with species accepted in shelter 111 | INSERT INTO Reference.Species (Species) 112 | VALUES ('Dog'), ('Cat'), ('Rabbit'), 113 | ('Ferret'), ('Raccoon');-- And a couple species for which we won't have any animals 114 | 115 | -- Species vital signs normal ranges 116 | CREATE TABLE Reference.Species_Vital_Signs_Ranges 117 | ( 118 | Species VARCHAR(10) NOT NULL PRIMARY KEY 119 | REFERENCES Reference.Species (Species), 120 | Temperature_Low DECIMAL(4, 1) NOT NULL, 121 | Temperature_High DECIMAL(4, 1) NOT NULL, 122 | Heart_Rate_Low TINYINT NOT NULL, 123 | Heart_Rate_high TINYINT NOT NULL, 124 | Respiratory_Rate_Low TINYINT NOT NULL, 125 | Respiratory_Rate_High TINYINT NOT NULL 126 | ); 127 | 128 | -- Source - various online veterinary sources 129 | INSERT INTO Reference.Species_Vital_Signs_Ranges 130 | (Species, Temperature_Low, Temperature_High, Heart_Rate_Low, Heart_Rate_high, Respiratory_Rate_Low, Respiratory_Rate_High) 131 | VALUES 132 | ('Dog', 99.5, 102.5, 60, 140, 10, 35), 133 | ('Cat', 99.5, 102.5, 140, 220, 20, 30), 134 | ('Rabbit', 100.5, 103.5, 120, 150, 30, 60); 135 | 136 | -- Breeds 137 | -- Sources: 138 | -- https://en.wikipedia.org/wiki/Lists_of_breeds 139 | -- https://github.com/paiv/fci-breeds/blob/master/fci-breeds.csv 140 | -- https://tica.org/breeds/browse-all-breeds 141 | -- https://rabbitpedia.com/ 142 | CREATE TABLE Reference.Breeds 143 | ( 144 | Species VARCHAR(10) NOT NULL 145 | REFERENCES Reference.Species (Species), 146 | Breed VARCHAR(50) NOT NULL, 147 | URL VARCHAR(128) NULL, 148 | PRIMARY KEY (Species, Breed), 149 | INDEX NCIDX_Breeds_Breed(Breed) 150 | ); 151 | 152 | -- Populate Breeds 153 | INSERT INTO Reference.Breeds (Species, Breed, URL) 154 | SELECT 'Dog' AS Species, 155 | LEFT(Breeds.Breed, 1) 156 | + RIGHT(LOWER(Breeds.Breed), LEN(Breeds.Breed) - 1) AS Breed, 157 | Breeds.URL 158 | FROM 159 | ( -- Data source was all caps to begin with 160 | VALUES 161 | ('ENGLISH POINTER', 'http://www.fci.be/en/nomenclature/ENGLISH-POINTER-1.html'), ('ENGLISH SETTER', 'http://www.fci.be/en/nomenclature/ENGLISH-SETTER-2.html'), 162 | ('KERRY BLUE TERRIER', 'http://www.fci.be/en/nomenclature/KERRY-BLUE-TERRIER-3.html'), ('CAIRN TERRIER', 'http://www.fci.be/en/nomenclature/CAIRN-TERRIER-4.html'), 163 | ('ENGLISH COCKER SPANIEL', 'http://www.fci.be/en/nomenclature/ENGLISH-COCKER-SPANIEL-5.html'), ('GORDON SETTER', 'http://www.fci.be/en/nomenclature/GORDON-SETTER-6.html'), 164 | ('AIREDALE TERRIER', 'http://www.fci.be/en/nomenclature/AIREDALE-TERRIER-7.html'), ('AUSTRALIAN TERRIER', 'http://www.fci.be/en/nomenclature/AUSTRALIAN-TERRIER-8.html'), 165 | ('BEDLINGTON TERRIER', 'http://www.fci.be/en/nomenclature/BEDLINGTON-TERRIER-9.html'), ('BORDER TERRIER', 'http://www.fci.be/en/nomenclature/BORDER-TERRIER-10.html'), 166 | ('BULL TERRIER', 'http://www.fci.be/en/nomenclature/BULL-TERRIER-11.html'), ('FOX TERRIER (SMOOTH)', 'http://www.fci.be/en/nomenclature/FOX-TERRIER-SMOOTH-12.html'), 167 | ('ENGLISH TOY TERRIER (BLACK &TAN)', 'http://www.fci.be/en/nomenclature/ENGLISH-TOY-TERRIER-BLACK-TAN-13.html'), ('SWEDISH VALLHUND', 'http://www.fci.be/en/nomenclature/SWEDISH-VALLHUND-14.html'), 168 | ('BELGIAN SHEPHERD', 'http://www.fci.be/en/nomenclature/BELGIAN-SHEPHERD-DOG-15.html'), ('OLD ENGLISH SHEEPDOG', 'http://www.fci.be/en/nomenclature/OLD-ENGLISH-SHEEPDOG-16.html'), 169 | ('GRIFFON NIVERNAIS', 'http://www.fci.be/en/nomenclature/GRIFFON-NIVERNAIS-17.html'), ('BRIQUET GRIFFON VENDEEN', 'http://www.fci.be/en/nomenclature/BRIQUET-GRIFFON-VENDEEN-19.html'), 170 | ('ARIEGEOIS', 'http://www.fci.be/en/nomenclature/ARIEGEOIS-20.html'), ('GASCON SAINTONGEOIS', 'http://www.fci.be/en/nomenclature/GASCON-SAINTONGEOIS-21.html'), 171 | ('GREAT GASCONY BLUE', 'http://www.fci.be/en/nomenclature/GREAT-GASCONY-BLUE-22.html'), ('POITEVIN', 'http://www.fci.be/en/nomenclature/POITEVIN-24.html'), ('BILLY', 'http://www.fci.be/en/nomenclature/BILLY-25.html'), 172 | ('ARTOIS HOUND', 'http://www.fci.be/en/nomenclature/ARTOIS-HOUND-28.html'), ('PORCELAINE', 'http://www.fci.be/en/nomenclature/PORCELAINE-30.html'), 173 | ('SMALL BLUE GASCONY', 'http://www.fci.be/en/nomenclature/SMALL-BLUE-GASCONY-31.html'), ('BLUE GASCONY GRIFFON', 'http://www.fci.be/en/nomenclature/BLUE-GASCONY-GRIFFON-32.html'), 174 | ('GRAND BASSET GRIFFON VENDEEN', 'http://www.fci.be/en/nomenclature/GRAND-BASSET-GRIFFON-VENDEEN-33.html'), ('NORMAN ARTESIEN BASSET', 'http://www.fci.be/en/nomenclature/NORMAN-ARTESIEN-BASSET-34.html'), 175 | ('BLUE GASCONY BASSET', 'http://www.fci.be/en/nomenclature/BLUE-GASCONY-BASSET-35.html'), ('BASSET FAUVE DE BRETAGNE', 'http://www.fci.be/en/nomenclature/BASSET-FAUVE-DE-BRETAGNE-36.html'), 176 | ('PORTUGUESE WATER', 'http://www.fci.be/en/nomenclature/PORTUGUESE-WATER-DOG-37.html'), ('WELSH CORGI (CARDIGAN)', 'http://www.fci.be/en/nomenclature/WELSH-CORGI-CARDIGAN-38.html'), 177 | ('WELSH CORGI (PEMBROKE)', 'http://www.fci.be/en/nomenclature/WELSH-CORGI-PEMBROKE-39.html'), ('IRISH SOFT COATED WHEATEN TERRIER', 'http://www.fci.be/en/nomenclature/IRISH-SOFT-COATED-WHEATEN-TERRIER-40.html'), 178 | ('YUGOSLAVIAN SHEPHERD DOG - SHARPLANINA', 'http://www.fci.be/en/nomenclature/YUGOSLAVIAN-SHEPHERD-DOG-SHARPLANINA-41.html'), ('JÄMTHUND', 'http://www.fci.be/en/nomenclature/JAMTHUND-42.html'), 179 | ('BASENJI', 'http://www.fci.be/en/nomenclature/BASENJI-43.html'), ('BERGER DE BEAUCE', 'http://www.fci.be/en/nomenclature/BERGER-DE-BEAUCE-44.html'), 180 | ('BERNESE MOUNTAIN', 'http://www.fci.be/en/nomenclature/BERNESE-MOUNTAIN-DOG-45.html'), ('APPENZELL CATTLE', 'http://www.fci.be/en/nomenclature/APPENZELL-CATTLE-DOG-46.html'), 181 | ('ENTLEBUCH CATTLE', 'http://www.fci.be/en/nomenclature/ENTLEBUCH-CATTLE-DOG-47.html'), ('KARELIAN BEAR', 'http://www.fci.be/en/nomenclature/KARELIAN-BEAR-DOG-48.html'), 182 | ('FINNISH SPITZ', 'http://www.fci.be/en/nomenclature/FINNISH-SPITZ-49.html'), ('NEWFOUNDLAND', 'http://www.fci.be/en/nomenclature/NEWFOUNDLAND-50.html'), 183 | ('FINNISH HOUND', 'http://www.fci.be/en/nomenclature/FINNISH-HOUND-51.html'), ('POLISH HOUND', 'http://www.fci.be/en/nomenclature/POLISH-HOUND-52.html'), 184 | ('KOMONDOR', 'http://www.fci.be/en/nomenclature/KOMONDOR-53.html'), ('KUVASZ', 'http://www.fci.be/en/nomenclature/KUVASZ-54.html'), 185 | ('PULI', 'http://www.fci.be/en/nomenclature/PULI-55.html'), ('PUMI', 'http://www.fci.be/en/nomenclature/PUMI-56.html'), 186 | ('HUNGARIAN SHORT-HAIRED POINTER (VIZSLA)', 'http://www.fci.be/en/nomenclature/HUNGARIAN-SHORT-HAIRED-POINTER-VIZSLA-57.html'), ('GREAT SWISS MOUNTAIN', 'http://www.fci.be/en/nomenclature/GREAT-SWISS-MOUNTAIN-DOG-58.html'), 187 | ('SWISS HOUND', 'http://www.fci.be/en/nomenclature/SWISS-HOUND-59.html'), ('SMALL SWISS HOUND', 'http://www.fci.be/en/nomenclature/SMALL-SWISS-HOUND-60.html'), 188 | ('ST. BERNARD', 'http://www.fci.be/en/nomenclature/ST-BERNARD-61.html'), ('COARSE-HAIRED STYRIAN HOUND', 'http://www.fci.be/en/nomenclature/COARSE-HAIRED-STYRIAN-HOUND-62.html'), 189 | ('AUSTRIAN BLACK AND TAN HOUND', 'http://www.fci.be/en/nomenclature/AUSTRIAN-BLACK-AND-TAN-HOUND-63.html'), ('AUSTRIAN PINSCHER', 'http://www.fci.be/en/nomenclature/AUSTRIAN-PINSCHER-64.html'), 190 | ('MALTESE', 'http://www.fci.be/en/nomenclature/MALTESE-65.html'), ('FAWN BRITTANY GRIFFON', 'http://www.fci.be/en/nomenclature/FAWN-BRITTANY-GRIFFON-66.html'), 191 | ('PETIT BASSET GRIFFON VENDEEN', 'http://www.fci.be/en/nomenclature/PETIT-BASSET-GRIFFON-VENDEEN-67.html'), ('TYROLEAN HOUND', 'http://www.fci.be/en/nomenclature/YROLEAN-HOUND-68.html'), 192 | ('LAKELAND TERRIER', 'http://www.fci.be/en/nomenclature/LAKELAND-TERRIER-70.html'), ('MANCHESTER TERRIER', 'http://www.fci.be/en/nomenclature/MANCHESTER-TERRIER-71.html'), 193 | ('NORWICH TERRIER', 'http://www.fci.be/en/nomenclature/NORWICH-TERRIER-72.html'), ('SCOTTISH TERRIER', 'http://www.fci.be/en/nomenclature/SCOTTISH-TERRIER-73.html'), 194 | ('SEALYHAM TERRIER', 'http://www.fci.be/en/nomenclature/SEALYHAM-TERRIER-74.html'), ('SKYE TERRIER', 'http://www.fci.be/en/nomenclature/SKYE-TERRIER-75.html'), 195 | ('STAFFORDSHIRE BULL TERRIER', 'http://www.fci.be/en/nomenclature/STAFFORDSHIRE-BULL-TERRIER-76.html'), 196 | ('CONTINENTAL TOY SPANIEL', 'http://www.fci.be/en/nomenclature/CONTINENTAL-TOY-SPANIEL-77.html'), 197 | ('WELSH TERRIER', 'http://www.fci.be/en/nomenclature/WELSH-TERRIER-78.html'), ('GRIFFON BRUXELLOIS', 'http://www.fci.be/en/nomenclature/GRIFFON-BRUXELLOIS-80.html'), 198 | ('GRIFFON BELGE', 'http://www.fci.be/en/nomenclature/GRIFFON-BELGE-81.html'), ('PETIT BRABANÇON', 'http://www.fci.be/en/nomenclature/PETIT-BRABANCON-82.html'), 199 | ('SCHIPPERKE', 'http://www.fci.be/en/nomenclature/SCHIPPERKE-83.html'), ('BLOODHOUND', 'http://www.fci.be/en/nomenclature/BLOODHOUND-84.html'), 200 | ('WEST HIGHLAND WHITE TERRIER', 'http://www.fci.be/en/nomenclature/WEST-HIGHLAND-WHITE-TERRIER-85.html'), 201 | ('YORKSHIRE TERRIER', 'http://www.fci.be/en/nomenclature/YORKSHIRE-TERRIER-86.html'), 202 | ('CATALAN SHEEPDOG', 'http://www.fci.be/en/nomenclature/CATALAN-SHEEPDOG-87.html'), ('SHETLAND SHEEPDOG', 'http://www.fci.be/en/nomenclature/SHETLAND-SHEEPDOG-88.html'), 203 | ('IBIZAN PODENCO', 'http://www.fci.be/en/nomenclature/IBIZAN-PODENCO-89.html'), ('BURGOS POINTING', 'http://www.fci.be/en/nomenclature/BURGOS-POINTING-DOG-90.html'), 204 | ('SPANISH MASTIFF', 'http://www.fci.be/en/nomenclature/SPANISH-MASTIFF-91.html'), 205 | ('PYRENEAN MASTIFF', 'http://www.fci.be/en/nomenclature/PYRENEAN-MASTIFF-92.html'), 206 | ('PORTUGUESE SHEEPDOG', 'http://www.fci.be/en/nomenclature/PORTUGUESE-SHEEPDOG-93.html'), ('PORTUGUESE WARREN HOUND-PORTUGUESE PODENGO', 'http://www.fci.be/en/nomenclature/PORTUGUESE-WARREN-HOUND-PORTUGUESE-PODENGO-94.html'), 207 | ('BRITTANY SPANIEL', 'http://www.fci.be/en/nomenclature/BRITTANY-SPANIEL-95.html'), ('RAFEIRO OF ALENTEJO', 'http://www.fci.be/en/nomenclature/RAFEIRO-OF-ALENTEJO-96.html'), 208 | ('GERMAN SPITZ', 'http://www.fci.be/en/nomenclature/GERMAN-SPITZ-97.html'), ('GERMAN WIRE- HAIRED POINTING', 'http://www.fci.be/en/nomenclature/GERMAN-WIRE-HAIRED-POINTING-DOG-98.html'), 209 | ('WEIMARANER', 'http://www.fci.be/en/nomenclature/WEIMARANER-99.html'), ('WESTPHALIAN DACHSBRACKE', 'http://www.fci.be/en/nomenclature/WESTPHALIAN-DACHSBRACKE-100.html'), 210 | ('FRENCH BULLDOG', 'http://www.fci.be/en/nomenclature/FRENCH-BULLDOG-101.html'), ('KLEINER MÜNSTERLÄNDER', 'http://www.fci.be/en/nomenclature/KLEINER-MUNSTERLANDER-102.html'), 211 | ('GERMAN HUNTING TERRIER', 'http://www.fci.be/en/nomenclature/GERMAN-HUNTING-TERRIER-103.html'), ('GERMAN SPANIEL', 'http://www.fci.be/en/nomenclature/GERMAN-SPANIEL-104.html'), 212 | ('FRENCH WATER', 'http://www.fci.be/en/nomenclature/FRENCH-WATER-DOG-105.html'), ('BLUE PICARDY SPANIEL', 'http://www.fci.be/en/nomenclature/BLUE-PICARDY-SPANIEL-106.html'), 213 | ('WIRE-HAIRED POINTING GRIFFON KORTHALS', 'http://www.fci.be/en/nomenclature/WIRE-HAIRED-POINTING-GRIFFON-KORTHALS-107.html'), ('PICARDY SPANIEL', 'http://www.fci.be/en/nomenclature/PICARDY-SPANIEL-108.html'), 214 | ('CLUMBER SPANIEL', 'http://www.fci.be/en/nomenclature/CLUMBER-SPANIEL-109.html'), ('CURLY COATED RETRIEVER', 'http://www.fci.be/en/nomenclature/CURLY-COATED-RETRIEVER-110.html'), 215 | ('GOLDEN RETRIEVER', 'http://www.fci.be/en/nomenclature/GOLDEN-RETRIEVER-111.html'), ('BRIARD', 'http://www.fci.be/en/nomenclature/BRIARD-113.html'), 216 | ('PONT-AUDEMER SPANIEL', 'http://www.fci.be/en/nomenclature/PONT-AUDEMER-SPANIEL-114.html'), ('SAINT GERMAIN POINTER', 'http://www.fci.be/en/nomenclature/SAINT-GERMAIN-POINTER-115.html'), 217 | ('DOGUE DE BORDEAUX', 'http://www.fci.be/en/nomenclature/DOGUE-DE-BORDEAUX-116.html'), ('DEUTSCH LANGHAAR', 'http://www.fci.be/en/nomenclature/DEUTSCH-LANGHAAR-117.html'), 218 | ('LARGE MUNSTERLANDER', 'http://www.fci.be/en/nomenclature/LARGE-MUNSTERLANDER-118.html'), ('GERMAN SHORT- HAIRED POINTING', 'http://www.fci.be/en/nomenclature/GERMAN-SHORT-HAIRED-POINTING-DOG-119.html'), 219 | ('IRISH RED SETTER', 'http://www.fci.be/en/nomenclature/IRISH-RED-SETTER-120.html'), ('FLAT COATED RETRIEVER', 'http://www.fci.be/en/nomenclature/FLAT-COATED-RETRIEVER-121.html'), 220 | ('LABRADOR RETRIEVER', 'http://www.fci.be/en/nomenclature/LABRADOR-RETRIEVER-122.html'), ('FIELD SPANIEL', 'http://www.fci.be/en/nomenclature/FIELD-SPANIEL-123.html'), 221 | ('IRISH WATER SPANIEL', 'http://www.fci.be/en/nomenclature/IRISH-WATER-SPANIEL-124.html'), ('ENGLISH SPRINGER SPANIEL', 'http://www.fci.be/en/nomenclature/ENGLISH-SPRINGER-SPANIEL-125.html'), 222 | ('WELSH SPRINGER SPANIEL', 'http://www.fci.be/en/nomenclature/WELSH-SPRINGER-SPANIEL-126.html'), ('SUSSEX SPANIEL', 'http://www.fci.be/en/nomenclature/SUSSEX-SPANIEL-127.html'), 223 | ('KING CHARLES SPANIEL', 'http://www.fci.be/en/nomenclature/KING-CHARLES-SPANIEL-128.html'), ('SMÅLANDSSTÖVARE', 'http://www.fci.be/en/nomenclature/SMALANDSSTOVARE-129.html'), 224 | ('DREVER', 'http://www.fci.be/en/nomenclature/DREVER-130.html'), ('SCHILLERSTÖVARE', 'http://www.fci.be/en/nomenclature/SCHILLERSTOVARE-131.html'), 225 | ('HAMILTONSTÖVARE', 'http://www.fci.be/en/nomenclature/HAMILTONSTOVARE-132.html'), ('FRENCH POINTING DOG - GASCOGNE TYPE', 'http://www.fci.be/en/nomenclature/FRENCH-POINTING-DOG-GASCOGNE-TYPE-133.html'), 226 | ('FRENCH POINTING DOG - PYRENEAN TYPE', 'http://www.fci.be/en/nomenclature/FRENCH-POINTING-DOG-PYRENEAN-TYPE-134.html'), ('SWEDISH LAPPHUND', 'http://www.fci.be/en/nomenclature/SWEDISH-LAPPHUND-135.html'), 227 | ('CAVALIER KING CHARLES SPANIEL', 'http://www.fci.be/en/nomenclature/CAVALIER-KING-CHARLES-SPANIEL-136.html'), ('PYRENEAN MOUNTAIN', 'http://www.fci.be/en/nomenclature/PYRENEAN-MOUNTAIN-DOG-137.html'), 228 | ('PYRENEAN SHEEPDOG - SMOOTH FACED', 'http://www.fci.be/en/nomenclature/PYRENEAN-SHEEPDOG-SMOOTH-FACED-138.html'), ('IRISH TERRIER', 'http://www.fci.be/en/nomenclature/IRISH-TERRIER-139.html'), 229 | ('BOSTON TERRIER', 'http://www.fci.be/en/nomenclature/BOSTON-TERRIER-140.html'), ('LONG-HAIRED PYRENEAN SHEEPDOG', 'http://www.fci.be/en/nomenclature/LONG-HAIRED-PYRENEAN-SHEEPDOG-141.html'), 230 | ('SLOVAKIAN CHUVACH', 'http://www.fci.be/en/nomenclature/SLOVAKIAN-CHUVACH-142.html'), 231 | ('DOBERMANN', 'http://www.fci.be/en/nomenclature/DOBERMANN-143.html'), 232 | ('BOXER', 'http://www.fci.be/en/nomenclature/BOXER-144.html'), ('LEONBERGER', 'http://www.fci.be/en/nomenclature/LEONBERGER-145.html'), 233 | ('RHODESIAN RIDGEBACK', 'http://www.fci.be/en/nomenclature/RHODESIAN-RIDGEBACK-146.html'), ('ROTTWEILER', 'http://www.fci.be/en/nomenclature/ROTTWEILER-147.html'), 234 | ('DACHSHUND', 'http://www.fci.be/en/nomenclature/DACHSHUND-148.html'), ('BULLDOG', 'http://www.fci.be/en/nomenclature/BULLDOG-149.html'), 235 | ('SERBIAN HOUND', 'http://www.fci.be/en/nomenclature/SERBIAN-HOUND-150.html'), ('ISTRIAN SHORT-HAIRED HOUND', 'http://www.fci.be/en/nomenclature/ISTRIAN-SHORT-HAIRED-HOUND-151.html'), 236 | ('ISTRIAN WIRE-HAIRED HOUND', 'http://www.fci.be/en/nomenclature/ISTRIAN-WIRE-HAIRED-HOUND-152.html'), ('DALMATIAN', 'http://www.fci.be/en/nomenclature/DALMATIAN-153.html'), 237 | ('POSAVATZ HOUND', 'http://www.fci.be/en/nomenclature/POSAVATZ-HOUND-154.html'), ('BOSNIAN BROKEN-HAIRED HOUND - CALLED BARAK', 'http://www.fci.be/en/nomenclature/BOSNIAN-BROKEN-HAIRED-HOUND-CALLED-BARAK-155.html'), 238 | ('COLLIE ROUGH', 'http://www.fci.be/en/nomenclature/COLLIE-ROUGH-156.html'), 239 | ('BULLMASTIFF', 'http://www.fci.be/en/nomenclature/BULLMASTIFF-157.html'), 240 | ('GREYHOUND', 'http://www.fci.be/en/nomenclature/GREYHOUND-158.html'), ('ENGLISH FOXHOUND', 'http://www.fci.be/en/nomenclature/ENGLISH-FOXHOUND-159.html'), 241 | ('IRISH WOLFHOUND', 'http://www.fci.be/en/nomenclature/IRISH-WOLFHOUND-160.html'), 242 | ('BEAGLE', 'http://www.fci.be/en/nomenclature/BEAGLE-161.html'), 243 | ('WHIPPET', 'http://www.fci.be/en/nomenclature/WHIPPET-162.html'), ('BASSET HOUND', 'http://www.fci.be/en/nomenclature/BASSET-HOUND-163.html'), 244 | ('DEERHOUND', 'http://www.fci.be/en/nomenclature/DEERHOUND-164.html'), ('ITALIAN SPINONE', 'http://www.fci.be/en/nomenclature/ITALIAN-SPINONE-165.html'), 245 | ('GERMAN SHEPHERD', 'http://www.fci.be/en/nomenclature/GERMAN-SHEPHERD-DOG-166.html'), ('AMERICAN COCKER SPANIEL', 'http://www.fci.be/en/nomenclature/AMERICAN-COCKER-SPANIEL-167.html'), 246 | ('DANDIE DINMONT TERRIER', 'http://www.fci.be/en/nomenclature/DANDIE-DINMONT-TERRIER-168.html'), ('FOX TERRIER (WIRE)', 'http://www.fci.be/en/nomenclature/FOX-TERRIER-WIRE-169.html'), 247 | ('CASTRO LABOREIRO', 'http://www.fci.be/en/nomenclature/CASTRO-LABOREIRO-DOG-170.html'), ('BOUVIER DES ARDENNES', 'http://www.fci.be/en/nomenclature/BOUVIER-DES-ARDENNES-171.html'), 248 | ('POODLE', 'http://www.fci.be/en/nomenclature/POODLE-172.html'), ('ESTRELA MOUNTAIN', 'http://www.fci.be/en/nomenclature/ESTRELA-MOUNTAIN-DOG-173.html'), 249 | ('FRENCH SPANIEL', 'http://www.fci.be/en/nomenclature/FRENCH-SPANIEL-175.html'), ('PICARDY SHEEPDOG', 'http://www.fci.be/en/nomenclature/PICARDY-SHEEPDOG-176.html'), 250 | ('ARIEGE POINTING', 'http://www.fci.be/en/nomenclature/ARIEGE-POINTING-DOG-177.html'), ('BOURBONNAIS POINTING', 'http://www.fci.be/en/nomenclature/BOURBONNAIS-POINTING-DOG-179.html'), 251 | ('AUVERGNE POINTER', 'http://www.fci.be/en/nomenclature/AUVERGNE-POINTER-180.html'), 252 | ('GIANT SCHNAUZER', 'http://www.fci.be/en/nomenclature/GIANT-SCHNAUZER-181.html'), 253 | ('SCHNAUZER', 'http://www.fci.be/en/nomenclature/SCHNAUZER-182.html'), ('MINIATURE SCHNAUZER', 'http://www.fci.be/en/nomenclature/MINIATURE-SCHNAUZER-183.html'), 254 | ('GERMAN PINSCHER', 'http://www.fci.be/en/nomenclature/GERMAN-PINSCHER-184.html'), ('MINIATURE PINSCHER', 'http://www.fci.be/en/nomenclature/MINIATURE-PINSCHER-185.html'), 255 | ('AFFENPINSCHER', 'http://www.fci.be/en/nomenclature/AFFENPINSCHER-186.html'), ('PORTUGUESE POINTING', 'http://www.fci.be/en/nomenclature/PORTUGUESE-POINTING-DOG-187.html'), 256 | ('SLOUGHI', 'http://www.fci.be/en/nomenclature/SLOUGHI-188.html'), ('FINNISH LAPPONIAN', 'http://www.fci.be/en/nomenclature/FINNISH-LAPPONIAN-DOG-189.html'), 257 | ('HOVAWART', 'http://www.fci.be/en/nomenclature/HOVAWART-190.html'), ('BOUVIER DES FLANDRES', 'http://www.fci.be/en/nomenclature/BOUVIER-DES-FLANDRES-191.html'), 258 | ('KROMFOHRLÄNDER', 'http://www.fci.be/en/nomenclature/KROMFOHRLANDER-192.html'), ('BORZOI - RUSSIAN HUNTING SIGHTHOUND', 'http://www.fci.be/en/nomenclature/BORZOI-RUSSIAN-HUNTING-SIGHTHOUND-193.html'), 259 | ('BERGAMASCO SHEPHERD', 'http://www.fci.be/en/nomenclature/BERGAMASCO-SHEPHERD-DOG-194.html'), ('ITALIAN VOLPINO', 'http://www.fci.be/en/nomenclature/ITALIAN-VOLPINO-195.html'), 260 | ('BOLOGNESE', 'http://www.fci.be/en/nomenclature/BOLOGNESE-196.html'), 261 | ('NEAPOLITAN MASTIFF', 'http://www.fci.be/en/nomenclature/NEAPOLITAN-MASTIFF-197.html'), 262 | ('ITALIAN ROUGH-HAIRED SEGUGIO', 'http://www.fci.be/en/nomenclature/ITALIAN-ROUGH-HAIRED-SEGUGIO-198.html'), ('CIRNECO DELL''ETNA', 'http://www.fci.be/en/nomenclature/CIRNECO-DELL-ETNA-199.html'), 263 | ('ITALIAN SIGHTHOUND', 'http://www.fci.be/en/nomenclature/ITALIAN-SIGHTHOUND-200.html'), ('MAREMMA AND THE ABRUZZES SHEEPDOG', 'http://www.fci.be/en/nomenclature/MAREMMA-AND-THE-ABRUZZES-SHEEPDOG-201.html'), 264 | ('ITALIAN POINTING', 'http://www.fci.be/en/nomenclature/ITALIAN-POINTING-DOG-202.html'), ('NORWEGIAN HOUND', 'http://www.fci.be/en/nomenclature/NORWEGIAN-HOUND-203.html'), 265 | ('SPANISH HOUND', 'http://www.fci.be/en/nomenclature/SPANISH-HOUND-204.html'), 266 | ('CHOW CHOW', 'http://www.fci.be/en/nomenclature/CHOW-CHOW-205.html'), 267 | ('JAPANESE CHIN', 'http://www.fci.be/en/nomenclature/JAPANESE-CHIN-206.html'), ('PEKINGESE', 'http://www.fci.be/en/nomenclature/PEKINGESE-207.html'), 268 | ('SHIH TZU', 'http://www.fci.be/en/nomenclature/SHIH-TZU-208.html'), ('TIBETAN TERRIER', 'http://www.fci.be/en/nomenclature/TIBETAN-TERRIER-209.html'), 269 | ('CANADIAN ESKIMO', 'http://www.fci.be/en/nomenclature/CANADIAN-ESKIMO-DOG-211.html'), 270 | ('SAMOYED', 'http://www.fci.be/en/nomenclature/SAMOYED-212.html'), 271 | ('HANOVERIAN SCENT HOUND', 'http://www.fci.be/en/nomenclature/HANOVERIAN-SCENT-HOUND-213.html'), ('HELLENIC HOUND', 'http://www.fci.be/en/nomenclature/HELLENIC-HOUND-214.html'), 272 | ('BICHON FRISE', 'http://www.fci.be/en/nomenclature/BICHON-FRISE-215.html'), ('PUDELPOINTER', 'http://www.fci.be/en/nomenclature/PUDELPOINTER-216.html'), 273 | ('BAVARIAN MOUNTAIN SCENT HOUND', 'http://www.fci.be/en/nomenclature/BAVARIAN-MOUNTAIN-SCENT-HOUND-217.html'), 274 | ('CHIHUAHUA', 'http://www.fci.be/en/nomenclature/CHIHUAHUA-218.html'), 275 | ('FRENCH TRICOLOUR HOUND', 'http://www.fci.be/en/nomenclature/FRENCH-TRICOLOUR-HOUND-219.html'), ('FRENCH WHITE & BLACK HOUND', 'http://www.fci.be/en/nomenclature/FRENCH-WHITE-BLACK-HOUND-220.html'), 276 | ('FRISIAN WATER', 'http://www.fci.be/en/nomenclature/FRISIAN-WATER-DOG-221.html'), ('STABIJHOUN', 'http://www.fci.be/en/nomenclature/STABIJHOUN-222.html'), 277 | ('DUTCH SHEPHERD', 'http://www.fci.be/en/nomenclature/DUTCH-SHEPHERD-DOG-223.html'), ('DRENTSCHE PARTRIDGE', 'http://www.fci.be/en/nomenclature/DRENTSCHE-PARTRIDGE-DOG-224.html'), 278 | ('FILA BRASILEIRO', 'http://www.fci.be/en/nomenclature/FILA-BRASILEIRO-225.html'), ('LANDSEER (EUROPEAN CONTINENTAL TYPE)', 'http://www.fci.be/en/nomenclature/LANDSEER-EUROPEAN-CONTINENTAL-TYPE-226.html'), 279 | ('LHASA APSO', 'http://www.fci.be/en/nomenclature/LHASA-APSO-227.html'), ('AFGHAN HOUND', 'http://www.fci.be/en/nomenclature/AFGHAN-HOUND-228.html'), 280 | ('SERBIAN TRICOLOUR HOUND', 'http://www.fci.be/en/nomenclature/SERBIAN-TRICOLOUR-HOUND-229.html'), ('TIBETAN MASTIFF', 'http://www.fci.be/en/nomenclature/TIBETAN-MASTIFF-230.html'), 281 | ('TIBETAN SPANIEL', 'http://www.fci.be/en/nomenclature/TIBETAN-SPANIEL-231.html'), ('DEUTSCH STICHELHAAR', 'http://www.fci.be/en/nomenclature/DEUTSCH-STICHELHAAR-232.html'), 282 | ('LITTLE LION', 'http://www.fci.be/en/nomenclature/LITTLE-LION-DOG-233.html'), ('XOLOITZCUINTLE', 'http://www.fci.be/en/nomenclature/XOLOITZCUINTLE-234.html'), 283 | ('GREAT DANE', 'http://www.fci.be/en/nomenclature/GREAT-DANE-235.html'), ('AUSTRALIAN SILKY TERRIER', 'http://www.fci.be/en/nomenclature/AUSTRALIAN-SILKY-TERRIER-236.html'), 284 | ('NORWEGIAN BUHUND', 'http://www.fci.be/en/nomenclature/NORWEGIAN-BUHUND-237.html'), ('MUDI', 'http://www.fci.be/en/nomenclature/MUDI-238.html'), 285 | ('HUNGARIAN WIRE-HAIRED POINTER', 'http://www.fci.be/en/nomenclature/HUNGARIAN-WIRE-HAIRED-POINTER-239.html'), ('HUNGARIAN GREYHOUND', 'http://www.fci.be/en/nomenclature/HUNGARIAN-GREYHOUND-240.html'), 286 | ('HUNGARIAN HOUND - TRANSYLVANIAN SCENT HOUND', 'http://www.fci.be/en/nomenclature/HUNGARIAN-HOUND-TRANSYLVANIAN-SCENT-HOUND-241.html'), ('NORWEGIAN ELKHOUND GREY', 'http://www.fci.be/en/nomenclature/NORWEGIAN-ELKHOUND-GREY-242.html'), 287 | ('ALASKAN MALAMUTE', 'http://www.fci.be/en/nomenclature/ALASKAN-MALAMUTE-243.html'), ('SLOVAKIAN HOUND', 'http://www.fci.be/en/nomenclature/SLOVAKIAN-HOUND-244.html'), 288 | ('BOHEMIAN WIRE-HAIRED POINTING GRIFFON', 'http://www.fci.be/en/nomenclature/BOHEMIAN-WIRE-HAIRED-POINTING-GRIFFON-245.html' ), ('CESKY TERRIER', 'http://www.fci.be/en/nomenclature/CESKY-TERRIER-246.html'), 289 | ('ATLAS MOUNTAIN DOG (AIDI)', 'http://www.fci.be/en/nomenclature/ATLAS-MOUNTAIN-DOG-AIDI-247.html'), ('PHARAOH HOUND', 'http://www.fci.be/en/nomenclature/PHARAOH-HOUND-248.html'), 290 | ('MAJORCA MASTIFF', 'http://www.fci.be/en/nomenclature/MAJORCA-MASTIFF-249.html'), ('HAVANESE', 'http://www.fci.be/en/nomenclature/HAVANESE-250.html'), 291 | ('POLISH LOWLAND SHEEPDOG', 'http://www.fci.be/en/nomenclature/POLISH-LOWLAND-SHEEPDOG-251.html'), ('TATRA SHEPHERD', 'http://www.fci.be/en/nomenclature\TATRA-SHEPHERD-DOG-252.html'), 292 | ('PUG', 'http://www.fci.be/en/nomenclature/PUG-253.html'), ('ALPINE DACHSBRACKE', 'http://www.fci.be/en/nomenclature/ALPINE-DACHSBRACKE-254.html'), 293 | ('AKITA', 'http://www.fci.be/en/nomenclature/AKITA-255.html'), ('SHIBA', 'http://www.fci.be/en/nomenclature/SHIBA-257.html'), 294 | ('JAPANESE TERRIER', 'http://www.fci.be/en/nomenclature/JAPANESE-TERRIER-259.html'), ('TOSA', 'http://www.fci.be/en/nomenclature\TOSA-260.html'), 295 | ('HOKKAIDO', 'http://www.fci.be/en/nomenclature/HOKKAIDO-261.html'), ('JAPANESE SPITZ', 'http://www.fci.be/en/nomenclature/JAPANESE-SPITZ-262.html'), 296 | ('CHESAPEAKE BAY RETRIEVER', 'http://www.fci.be/en/nomenclature/CHESAPEAKE-BAY-RETRIEVER-263.html'), ('MASTIFF', 'http://www.fci.be/en/nomenclature/MASTIFF-264.html'), 297 | ('NORWEGIAN LUNDEHUND', 'http://www.fci.be/en/nomenclature/NORWEGIAN-LUNDEHUND-265.html'), ('HYGEN HOUND', 'http://www.fci.be/en/nomenclature/HYGEN-HOUND-266.html'), 298 | ('HALDEN HOUND', 'http://www.fci.be/en/nomenclature/HALDEN-HOUND-267.html'), ('NORWEGIAN ELKHOUND BLACK', 'http://www.fci.be/en/nomenclature/NORWEGIAN-ELKHOUND-BLACK-268.html'), 299 | ('SALUKI', 'http://www.fci.be/en/nomenclature/SALUKI-269.html'), 300 | ('SIBERIAN HUSKY', 'http://www.fci.be/en/nomenclature/SIBERIAN-HUSKY-270.html'), 301 | ('BEARDED COLLIE', 'http://www.fci.be/en/nomenclature/BEARDED-COLLIE-271.html'), ('NORFOLK TERRIER', 'http://www.fci.be/en/nomenclature/NORFOLK-TERRIER-272.html'), 302 | ('CANAAN', 'http://www.fci.be/en/nomenclature/CANAAN-DOG-273.html'), ('GREENLAND', 'http://www.fci.be/en/nomenclature/GREENLAND-DOG-274.html'), 303 | ('NORRBOTTENSPITZ', 'http://www.fci.be/en/nomenclature/NORRBOTTENSPITZ-276.html'), ('CROATIAN SHEPHERD', 'http://www.fci.be/en/nomenclature/CROATIAN-SHEPHERD-DOG-277.html'), 304 | ('KARST SHEPHERD', 'http://www.fci.be/en/nomenclature/KARST-SHEPHERD-DOG-278.html'), ('MONTENEGRIN MOUNTAIN HOUND', 'http://www.fci.be/en/nomenclature/MONTENEGRIN-MOUNTAIN-HOUND-279.html'), 305 | ('OLD DANISH POINTING', 'http://www.fci.be/en/nomenclature/OLD-DANISH-POINTING-DOG-281.html'), ('GRAND GRIFFON VENDEEN', 'http://www.fci.be/en/nomenclature/GRAND-GRIFFON-VENDEEN-282.html'), 306 | ('COTON DE TULEAR', 'http://www.fci.be/en/nomenclature/COTON-DE-TULEAR-283.html'), ('LAPPONIAN HERDER', 'http://www.fci.be/en/nomenclature/LAPPONIAN-HERDER-284.html'), 307 | ('SPANISH GREYHOUND', 'http://www.fci.be/en/nomenclature/SPANISH-GREYHOUND-285.html'), 308 | ('AMERICAN STAFFORDSHIRE TERRIER', 'http://www.fci.be/en/nomenclature/AMERICAN-STAFFORDSHIRE-TERRIER-286.html'), 309 | ('AUSTRALIAN CATTLE', 'http://www.fci.be/en/nomenclature/AUSTRALIAN-CATTLE-DOG-287.html'), ('CHINESE CRESTED', 'http://www.fci.be/en/nomenclature/CHINESE-CRESTED-DOG-288.html'), 310 | ('ICELANDIC SHEEPDOG', 'http://www.fci.be/en/nomenclature/ICELANDIC-SHEEPDOG-289.html'), 311 | ('BEAGLE HARRIER', 'http://www.fci.be/en/nomenclature/BEAGLE-HARRIER-290.html'), 312 | ('EURASIAN', 'http://www.fci.be/en/nomenclature/EURASIAN-291.html'), ('DOGO ARGENTINO', 'http://www.fci.be/en/nomenclature/DOGO-ARGENTINO-292.html'), 313 | ('AUSTRALIAN KELPIE', 'http://www.fci.be/en/nomenclature/AUSTRALIAN-KELPIE-293.html'), ('OTTERHOUND', 'http://www.fci.be/en/nomenclature/OTTERHOUND-294.html'), 314 | ('HARRIER', 'http://www.fci.be/en/nomenclature/HARRIER-295.html'), ('COLLIE SMOOTH', 'http://www.fci.be/en/nomenclature/COLLIE-SMOOTH-296.html'), 315 | ('BORDER COLLIE', 'http://www.fci.be/en/nomenclature/BORDER-COLLIE-297.html'), ('ROMAGNA WATER', 'http://www.fci.be/en/nomenclature/ROMAGNA-WATER-DOG-298.html'), 316 | ('GERMAN HOUND', 'http://www.fci.be/en/nomenclature/GERMAN-HOUND-299.html'), ('BLACK AND TAN COONHOUND', 'http://www.fci.be/en/nomenclature/BLACK-AND-TAN-COONHOUND-300.html'), 317 | ('AMERICAN WATER SPANIEL', 'http://www.fci.be/en/nomenclature/AMERICAN-WATER-SPANIEL-301.html'), ('IRISH GLEN OF IMAAL TERRIER', 'http://www.fci.be/en/nomenclature/IRISH-GLEN-OF-IMAAL-TERRIER-302.html'), 318 | ('AMERICAN FOXHOUND', 'http://www.fci.be/en/nomenclature/AMERICAN-FOXHOUND-303.html'), ('RUSSIAN-EUROPEAN LAIKA', 'http://www.fci.be/en/nomenclature/RUSSIAN-EUROPEAN-LAIKA-304.html'), 319 | ('EAST SIBERIAN LAIKA', 'http://www.fci.be/en/nomenclature/EAST-SIBERIAN-LAIKA-305.html'), ('WEST SIBERIAN LAIKA', 'http://www.fci.be/en/nomenclature/WEST-SIBERIAN-LAIKA-306.html'), 320 | ('AZAWAKH', 'http://www.fci.be/en/nomenclature/AZAWAKH-307.html'), ('DUTCH SMOUSHOND', 'http://www.fci.be/en/nomenclature/DUTCH-SMOUSHOND-308.html'), 321 | ('SHAR PEI', 'http://www.fci.be/en/nomenclature/SHAR-PEI-309.html'), ('PERUVIAN HAIRLESS', 'http://www.fci.be/en/nomenclature/PERUVIAN-HAIRLESS-DOG-310.html'), 322 | ('SAARLOOS WOLFHOND', 'http://www.fci.be/en/nomenclature/SAARLOOS-WOLFHOND-311.html'), ('NOVA SCOTIA DUCK TOLLING RETRIEVER', 'http://www.fci.be/en/nomenclature/NOVA-SCOTIA-DUCK-TOLLING-RETRIEVER-312.html'), 323 | ('DUTCH SCHAPENDOES', 'http://www.fci.be/en/nomenclature/DUTCH-SCHAPENDOES-313.html'), ('NEDERLANDSE KOOIKERHONDJE', 'http://www.fci.be/en/nomenclature/NEDERLANDSE-KOOIKERHONDJE-314.html'), 324 | ('BROHOLMER', 'http://www.fci.be/en/nomenclature/BROHOLMER-315.html'), ('FRENCH WHITE AND ORANGE HOUND', 'http://www.fci.be/en/nomenclature/FRENCH-WHITE-AND-ORANGE-HOUND-316.html'), 325 | ('KAI', 'http://www.fci.be/en/nomenclature/KAI-317.html'), ('KISHU', 'http://www.fci.be/en/nomenclature/KISHU-318.html'), 326 | ('SHIKOKU', 'http://www.fci.be/en/nomenclature/SHIKOKU-319.html'), ('WIREHAIRED SLOVAKIAN POINTER', 'http://www.fci.be/en/nomenclature/WIREHAIRED-SLOVAKIAN-POINTER-320.html'), 327 | ('MAJORCA SHEPHERD', 'http://www.fci.be/en/nomenclature/MAJORCA-SHEPHERD-DOG-321.html'), ('GREAT ANGLO-FRENCH TRICOLOUR HOUND', 'http://www.fci.be/en/nomenclature/GREAT-ANGLO-FRENCH-TRICOLOUR-HOUND-322.html'), 328 | ('GREAT ANGLO-FRENCH WHITE AND BLACK HOUND', 'http://www.fci.be/en/nomenclature/GREAT-ANGLO-FRENCH-WHITE-AND-BLACK-HOUND-323.html'), ('GREAT ANGLO-FRENCH WHITE & ORANGE HOUND', 'http://www.fci.be/en/nomenclature/GREAT-ANGLO-FRENCH-WHITE-ORANGE-HOUND-324.html'), 329 | ('MEDIUM-SIZED ANGLO-FRENCH HOUND', 'http://www.fci.be/en/nomenclature/MEDIUM-SIZED-ANGLO-FRENCH-HOUND-325.html'), ('SOUTH RUSSIAN SHEPHERD', 'http://www.fci.be/en/nomenclature/SOUTH-RUSSIAN-SHEPHERD-DOG-326.html'), 330 | ('RUSSIAN BLACK TERRIER', 'http://www.fci.be/en/nomenclature/RUSSIAN-BLACK-TERRIER-327.html'), ('CAUCASIAN SHEPHERD', 'http://www.fci.be/en/nomenclature/CAUCASIAN-SHEPHERD-DOG-328.html'), 331 | ('CANARIAN WARREN HOUND', 'http://www.fci.be/en/nomenclature/CANARIAN-WARREN-HOUND-329.html'), ('IRISH RED AND WHITE SETTER', 'http://www.fci.be/en/nomenclature/IRISH-RED-AND-WHITE-SETTER-330.html'), 332 | ('KANGAL SHEPHERD', 'http://www.fci.be/en/nomenclature/KANGAL-SHEPHERD-DOG-331.html'), ('CZECHOSLOVAKIAN WOLFDOG', 'http://www.fci.be/en/nomenclature/CZECHOSLOVAKIAN-WOLFDOG-332.html'), 333 | ('POLISH GREYHOUND', 'http://www.fci.be/en/nomenclature/POLISH-GREYHOUND-333.html'), ('KOREA JINDO', 'http://www.fci.be/en/nomenclature/KOREA-JINDO-DOG-334.html'), 334 | ('CENTRAL ASIA SHEPHERD', 'http://www.fci.be/en/nomenclature/CENTRAL-ASIA-SHEPHERD-DOG-335.html'), ('SPANISH WATER', 'http://www.fci.be/en/nomenclature/SPANISH-WATER-DOG-336.html'), 335 | ('ITALIAN SHORT-HAIRED SEGUGIO', 'http://www.fci.be/en/nomenclature/ITALIAN-SHORT-HAIRED-SEGUGIO-337.html'), ('THAI RIDGEBACK', 'http://www.fci.be/en/nomenclature\THAI-RIDGEBACK-DOG-338.html'), 336 | ('PARSON RUSSELL TERRIER', 'http://www.fci.be/en/nomenclature/PARSON-RUSSELL-TERRIER-339.html'), ('SAINT MIGUEL CATTLE', 'http://www.fci.be/en/nomenclature/SAINT-MIGUEL-CATTLE-DOG-340.html'), 337 | ('BRAZILIAN TERRIER', 'http://www.fci.be/en/nomenclature/BRAZILIAN-TERRIER-341.html'), ('AUSTRALIAN SHEPHERD', 'http://www.fci.be/en/nomenclature/AUSTRALIAN-SHEPHERD-342.html'), 338 | ('ITALIAN CANE CORSO', 'http://www.fci.be/en/nomenclature/ITALIAN-CANE-CORSO-343.html'), ('AMERICAN AKITA', 'http://www.fci.be/en/nomenclature/AMERICAN-AKITA-344.html'), 339 | ('JACK RUSSELL TERRIER', 'http://www.fci.be/en/nomenclature/JACK-RUSSELL-TERRIER-345.html'), ('DOGO CANARIO', 'http://www.fci.be/en/nomenclature/DOGO-CANARIO-346.html')--, 340 | ('WHITE SWISS SHEPHERD', 'http://www.fci.be/en/nomenclature/WHITE-SWISS-SHEPHERD-DOG-347.html'), ('TAIWAN', 'http://www.fci.be/en/nomenclature/TAIWAN-DOG-348.html'), 341 | ('ROMANIAN MIORITIC SHEPHERD', 'http://www.fci.be/en/nomenclature/ROMANIAN-MIORITIC-SHEPHERD-DOG-349.html'), ('ROMANIAN CARPATHIAN SHEPHERD', 'http://www.fci.be/en/nomenclature/ROMANIAN-CARPATHIAN-SHEPHERD-DOG-350.html'), 342 | ('AUSTRALIAN STUMPY TAIL CATTLE', 'http://www.fci.be/en/nomenclature/AUSTRALIAN-STUMPY-TAIL-CATTLE-DOG-351.html'), ('RUSSIAN TOY', 'http://www.fci.be/en/nomenclature/RUSSIAN-TOY-352.html'), 343 | ('CIMARRÓN URUGUAYO', 'http://www.fci.be/en/nomenclature/CIMARRON-URUGUAYO-353.html'), ('POLISH HUNTING', 'http://www.fci.be/en/nomenclature/POLISH-HUNTING-DOG-354.html'), 344 | ('BOSNIAN AND HERZEGOVINIAN - CROATIAN SHEPHERD', 'http://www.fci.be/en/nomenclature/BOSNIAN-AND-HERZEGOVINIAN-CROATIAN-SHEPHERD-DOG-355.html'), 345 | ('DANISH-SWEDISH FARMDOG', 'http://www.fci.be/en/nomenclature/DANISH-SWEDISH-FARMDOG-356.html'), ('ROMANIAN BUCOVINA SHEPHERD', 'http://www.fci.be/en/nomenclature/ROMANIAN-BUCOVINA-SHEPHERD-357.html'), 346 | ('THAI BANGKAEW', 'http://www.fci.be/en/nomenclature/THAI-BANGKAEW-DOG-358.html'), ('MINIATURE BULL TERRIER', 'http://www.fci.be/en/nomenclature/MINIATURE-BULL-TERRIER-359.html'), 347 | ('LANCASHIRE HEELER', 'http://www.fci.be/en/nomenclature/LANCASHIRE-HEELER-360.html'), ('SEGUGIO MAREMMANO', 'http://www.fci.be/en/nomenclature/SEGUGIO-MAREMMANO-361.html') 348 | ) AS Breeds (Breed, URL) 349 | UNION ALL 350 | SELECT 'Cat', 351 | Breeds.Breed, 352 | 'https://tica.org/breeds/browse-all-breeds#' + REPLACE(LOWER(Breeds.Breed), ' ', '-') 353 | FROM 354 | ( 355 | VALUES ('American Bobtail'),('Bengal'), ('Maine Coon'), 356 | ('Persian'),('Ragdoll'),('Russian Blue'), ('Scottish Fold'), ('Siamese'), ('Sphynx'),('Turkish Angora') 357 | ('Abyssinian'), ('American Bobtail'), ('American Bobtail Shorthair'), ('American Curl'),('American Shorthair'), ('American Wirehair'), ('Australian Mist'), ('Balinese'), 358 | ('Bengal'), ('Bengal Longhair'), ('Birman'), ('Bombay'), ('British Longhair'), ('British Shorthair'), ('Burmese'), ('Burmilla'), 359 | ('Burmilla Longhair'), ('Chartreux'), ('Chausie'), ('Cornish Rex'), ('Cymric'), ('Devon Rex'), ('Donskoy'), ('Egyptian Mau'), ('Exotic Shorthair'), ('Havana'), ('Himalayan'), ('Japanese Bobtail'), 360 | ('Japanese Bobtail Longhair'), ('Khaomanee'), ('Korat'), ('Kurilian Bobtail'), ('Kurilian Bobtail Longhair'), ('LaPerm'), ('LaPerm Shorthair'), ('Lykoi'), ('Maine Coon'), ('Maine Coon Polydactyl'), ('Manx'), ('Minuet'), 361 | ('Minuet Longhair'), ('Munchkin'), ('Munchkin Longhair'), ('Nebelung'), ('Norwegian Forest'), ('Ocicat'), ('Oriental Longhair'), ('Oriental Shorthair'), 362 | ('Persian'), ('Peterbald'), ('Pixiebob'), ('Pixiebob Longhair'), ('Ragdoll'), ('Russian Blue'), ('Savannah'), ('Scottish Fold'), 363 | ('Scottish Fold Longhair'), ('Scottish Straight'), ('Scottish Straight Longhair'), ('Selkirk Rex'), ('Selkirk Rex Longhair'), ('Siamese'), ('Siberian'), ('Singapura'), ('Snowshoe'), ('Somali'), ('Sphynx'), ('Thai'), 364 | ('Tonkinese'), ('Toyger'), ('Turkish Angora'), ('Turkish Van') 365 | ) AS Breeds (Breed) 366 | UNION ALL 367 | SELECT 'Rabbit', 368 | Breeds.Breed, 369 | 'https://rabbitpedia.com/' + REPLACE(Breeds.Breed, ' ', '-') 370 | FROM 371 | ( 372 | VALUES ('Lionhead'),('English Lop'), ('French Lop'),('American'),('Belgian Hare'),('Californian'),('Chinchilla (Giant)'), ('English Angora'), 373 | ('Satin Angora'),('Himalayan'), ('Jersey Wooly'), ('Velveteen Lop') 374 | 375 | ('Lionhead'), ('Flemish Giant'), ('Continental Giant'), ('Dutch'), ('English Lop'), ('French Lop'), ('Holland Lop'), ('Mini Rex'), 376 | ('Netherland dwarf'), ('Polish'), ('American'), ('American Fuzzy Lop'), ('American Sable'), ('Argente Brun'), ('Argente Crème'), ('Argente de Champagne'), 377 | ('Belgian Hare'), ('Beveren'), ('Blanc de Hotot'), ('Britannia Petite'), ('Californian'), ('Checkered Giant'), ('Chinchilla (Standard)'), ('Chinchilla (American)'), 378 | ('Chinchilla (Giant)'), ('Cinnamon'), ('Dwarf Hotot'), ('Dwarf Lop (Mini Lop in USA)'), ('English Angora'), ('English Spot'), ('Florida White'), ('French Angora'), 379 | ('Giant Angora'), ('Giant Papillon'), ('Harlequin'), ('Havana'), ('Himalayan'), ('Jersey Wooly'), ('Lilac'), ('New Zealand'), 380 | ('Palomino'), ('Rex (Standard)'), ('Rhinelander'), ('Satin'), ('Satin Angora'), ('Silver'), ('Silver Fox'), ('Silver Marten'), ('Tan'), ('Thrianta'), ('Velveteen Lop') 381 | ) AS Breeds (Breed); 382 | 383 | -- Popular animal names 384 | -- Sources: 385 | -- https://www.rover.com/blog/dog-names/ 386 | -- https://www.rover.com/blog/best-cat-names/ 387 | -- https://petset.com/pet-names/popular-bunny-names/ 388 | CREATE TABLE Reference.Common_Animal_Names 389 | ( 390 | Species VARCHAR(10) NOT NULL 391 | REFERENCES Reference.Species (Species), 392 | [Rank] TINYINT NOT NULL, 393 | Male VARCHAR(20) NOT NULL, 394 | Female VARCHAR(20) NOT NULL, 395 | PRIMARY KEY (Species, [Rank]), 396 | INDEX NCIDX_Common_Animal_Names__Rank ([Rank]) 397 | ); 398 | 399 | INSERT INTO Reference.Common_Animal_Names (Species, [Rank], Male, Female) 400 | SELECT 'Dog', 401 | CAST(Names.Rank AS TINYINT), 402 | Names.Male, 403 | Names.Female 404 | FROM 405 | ( 406 | VALUES ('Max', 'Bella', '1'), ('Charlie', 'Luna', '2'), ('Cooper', 'Lucy', '3'), ('Buddy', 'Daisy', '4'), ('Rocky', 'Lily', '5'), ('Milo', 'Zoe', '6'), ('Jack', 'Lola', '7'), ('Bear', 'Molly', '8'), 407 | ('Duke', 'Sadie', '9'), ('Teddy', 'Bailey', '10'), ('Oliver', 'Stella', '11'), ('Bentley', 'Maggie', '12'), ('Tucker', 'Roxy', '13'), ('Beau', 'Sophie', '14'), ('Leo', 'Chloe', '15'), ('Toby', 'Penny', '16'), 408 | ('Jax', 'Coco', '17'), ('Zeus', 'Nala', '18'), ('Winston', 'Rosie', '19'), ('Blue', 'Ruby', '20'), ('Finn', 'Gracie', '21'), ('Louie', 'Ellie', '22'), ('Ollie', 'Mia', '23'), ('Murphy', 'Piper', '24'), 409 | ('Gus', 'Callie', '25'), ('Moose', 'Abby', '26'), ('Jake', 'Lexi', '27'), ('Loki', 'Ginger', '28'), ('Dexter', 'Lulu', '29'), ('Hank', 'Pepper', '30'), ('Bruno', 'Willow', '31'), ('Apollo', 'Riley', '32'), 410 | ('Buster', 'Millie', '33'), ('Thor', 'Harley', '34'), ('Bailey', 'Sasha', '35'), ('Gunnar', 'Lady', '36'), ('Lucky', 'Izzy', '37'), ('Diesel', 'Layla', '38'), ('Harley', 'Charlie', '39'), ('Henry', 'Dixie', '40'), 411 | ('Koda', 'Maya', '41'), ('Jackson', 'Annie', '42'), ('Riley', 'Kona', '43'), ('Ace', 'Hazel', '44'), ('Oscar', 'Winnie', '45'), ('Chewy', 'Olive', '46'), ('Bandit', 'Princess', '47'), ('Baxter', 'Emma', '48'), 412 | ('Scout', 'Athena', '49'), ('Jasper', 'Nova', '50'), ('Maverick', 'Belle', '51'), ('Sam', 'Honey', '52'), ('Cody', 'Ella', '53'), ('Gizmo', 'Marley', '54'), ('Shadow', 'Cookie', '55'), ('Simba', 'Maddie', '56'), 413 | ('Rex', 'Remi / Remy', '57'), ('Brody', 'Phoebe', '58'), ('Tank', 'Scout', '59'), ('Marley', 'Minnie', '60'), ('Otis', 'Dakota', '61'), ('Remi / Remy', 'Holly', '62'), ('Roscoe', 'Angel', '63'), ('Rocco', 'Josie', '64'), 414 | ('Sammy', 'Leia', '65'), ('Cash', 'Harper', '66'), ('Boomer', 'Ava', '67'), ('Prince', 'Missy', '68'), ('Benji', 'Mila', '69'), ('Benny', 'Sugar', '70'), ('Copper', 'Shelby', '71'), ('Archie', 'Poppy', '72'), 415 | ('Chance', 'Blue', '73'), ('Ranger', 'Mocha', '74'), ('Ziggy', 'Cleo', '75'), ('Luke', 'Penelope', '76'), ('George', 'Ivy', '77'), ('Oreo', 'Peanut', '78'), ('Hunter', 'Fiona', '79'), ('Rusty', 'Xena', '80'), 416 | ('King', 'Gigi', '81'), ('Odin', 'Sandy', '82'), ('Coco', 'Bonnie', '83'), ('Frankie', 'Jasmine', '84'), ('Tyson', 'Baby', '85'), ('Chase', 'Macy', '86'), ('Theo', 'Paisley', '87'), ('Romeo', 'Shadow', '88'), 417 | ('Bruce', 'Koda', '89'), ('Rudy', 'Pearl', '90'), ('Zeke', 'Skye', '91'), ('Kobe', 'Delilah', '92'), ('Peanut', 'Nina', '93'), ('Joey', 'Trixie', '94'), ('Oakley', 'Charlotte', '95'), ('Chico', 'Aspen', '96'), 418 | ('Mac', 'Arya', '97'), ('Walter', 'Diamond', '98'), ('Brutus', 'Georgia', '99'), ('Samson', 'Dolly', '100') 419 | ) AS Names (Male, Female, [Rank]) 420 | UNION ALL 421 | SELECT 'Cat', 422 | CAST(Names.Rank AS TINYINT), 423 | Names.Male, 424 | Names.Female 425 | FROM 426 | ( 427 | VALUES ('Oliver', 'Luna', '1'), ('Leo', 'Bella', '2'), ('Milo', 'Lily', '3'), ('Charlie', 'Lucy', '4'), ('Max', 'Kitty', '5'), ('Jack', 'Callie', '6'), ('Simba', 'Nala', '7'), ('Loki', 'Zoe', '8'), 428 | ('Oscar', 'Chloe', '9'), ('Jasper', 'Sophie', '10'), ('Buddy', 'Daisy', '11'), ('Tiger', 'Stella', '12'), ('Toby', 'Cleo', '13'), ('George', 'Lola', '14'), ('Smokey', 'Gracie', '15'), ('Simon', 'Mia', '16'), 429 | ('Tigger', 'Molly', '17'), ('Ollie', 'Penny', '18'), ('Louie', 'Willow', '19'), ('Felix', 'Olive', '20'), ('Dexter', 'Kiki', '21'), ('Shadow', 'Pepper', '22'), ('Finn', 'Princess', '23'), ('Henry', 'Rosie', '24'), 430 | ('Kitty', 'Ellie', '25'), ('Oreo', 'Maggie', '26'), ('Gus', 'Coco', '27'), ('Binx', 'Piper', '28'), ('Winston', 'Lulu', '29'), ('Sam', 'Sadie', '30'), ('Rocky', 'Izzy', '31'), ('Gizmo', 'Ginger', '32'), 431 | ('Sammy', 'Abby', '33'), ('Jax', 'Sasha', '34'), ('Sebastian', 'Pumpkin', '35'), ('Blu', 'Ruby', '36'), ('Theo', 'Shadow', '37'), ('Beau', 'Phoebe', '38'), ('Salem', 'Millie', '39'), ('Chester', 'Roxy', '40'), 432 | ('Lucky', 'Minnie', '41'), ('Frankie', 'Baby', '42'), ('Boots', 'Fiona', '43'), ('Cooper', 'Jasmine', '44'), ('Thor', 'Penelope', '45'), ('Bear', 'Sassy', '46'), ('Romeo', 'Charlie', '47'), ('Teddy', 'Oreo', '48'), 433 | ('Bandit', 'Mittens', '49'), ('Ziggy', 'Boo', '50'), ('Apollo', 'Belle', '51'), ('Pumpkin', 'Misty', '52'), ('Boo', 'Mimi', '53'), ('Zeus', 'Missy', '54'), ('Bob', 'Emma', '55'), ('Tucker', 'Annie', '56'), 434 | ('Jackson', 'Athena', '57'), ('Tom', 'Hazel', '58'), ('Cosmo', 'Angel', '59'), ('Bruce', 'Ella', '60'), ('Murphy', 'Cookie', '61'), ('Buster', 'Bailey', '62'), ('Midnight', 'Arya', '63'), ('Moose', 'Nova', '64'), 435 | ('Merlin', 'Olivia', '65'), ('Frank', 'Zelda', '66'), ('Joey', 'Maya', '67'), ('Thomas', 'Smokey', '68'), ('Harley', 'Peanut', '69'), ('Prince', 'Poppy', '70'), ('Archie', 'Midnight', '71'), ('Tommy', 'Winnie', '72'), 436 | ('Marley', 'Patches', '73'), ('Otis', 'Charlotte', '74'), ('Casper', 'Layla', '75'), ('Harry', 'Leia', '76'), ('Benny', 'Delilah', '77'), ('Percy', 'Alice', '78'), ('Bentley', 'Harley', '79'), ('Jake', 'Pearl', '80'), 437 | ('Ozzy', 'Ivy', '81'), ('Ash', 'Lexi', '82'), ('Sylvester', 'Peaches', '83'), ('Mickey', 'Mila', '84'), ('Fred', 'Gypsy', '85'), ('Walter', 'Miss Kitty', '86'), ('Clyde', 'Kitten', '87'), ('Pepper', 'Cat', '88'), 438 | ('Calvin', 'Snickers', '89'), ('Tux', 'Scout', '90'), ('Stanley', 'Blu', '91'), ('Garfield', 'Lucky', '92'), ('Louis', 'Freya', '93'), ('Mowgli', 'Tiger', '94'), ('Mac', 'Stormy', '95'), ('Luke', 'Jade', '96'), 439 | ('Sunny', 'Honey', '97'), ('Duke', 'Marley', '98'), ('Hobbes', 'Frankie', '99'), ('Remi', 'Gigi', '100') 440 | ) AS Names (Male, Female, Rank) 441 | UNION ALL 442 | SELECT 'Rabbit', 443 | CAST(Names.Rank AS TINYINT), 444 | LEFT(Names.Male, 1) + RIGHT(LOWER(Names.Male), LEN(Names.Male) - 1), 445 | LEFT(Names.Female, 1) + RIGHT(LOWER(Names.Female), LEN(Names.Female) - 1) 446 | FROM 447 | ( -- Data source was all caps to begin with 448 | VALUES ('JELLY BEAN', 'WILLOW', '1'), ('SNOWBALL', 'PEACHES', '2'), ('PEANUT', 'SPRINKLES', '3'), ('SNOOP', 'SUNNY', '4'), ('THUMPER', 'BON BON', '5'), ('OLIVER', 'MAGGIE', '6'), ('COMET', 'SNOWY', '7'), ('STUART', 'LILLY', '8'), 449 | ('MIDNIGHT', 'FLOWER', '9'), ('BILLY', 'SUGAR', '10'), ('CARAMEL', 'ANGEL', '11'), ('FREDDIE', 'SWEET PEA', '12'), ('PEPPER', 'SNOWFLAKE', '13'), ('RILEY', 'LICORICE', '14'), ('HOPPER', 'LUNA', '15'), ('PANCAKE', 'DAISY', '16'), 450 | ('SPOOKY', 'NALA', '17'), ('CHIP', 'GERTIE', '18'), ('DUSTY', 'MILLY', '19'), ('JESSE', 'COOKIE', '20'), ('BREEZE', 'JULIET', '21'), ('DARRYL', 'TWINKLE', '22'), ('SAGE', 'WHITNEY', '23'), ('JASPER', 'MOLLY', '24'), 451 | ('HUGO', 'APRIL', '25'), ('MARBLE', 'COCO', '26'), ('DANTE', 'REMI', '27'), ('ARCHIE', 'KATRINA', '28'), ('SPANKY', 'OLIVE', '29'), ('SHIPPY', 'PRINCESS', '30'), ('GIZMO', 'NEELA', '31'), ('RIVER', 'ROXANNE', '32'), 452 | ('GUS', 'KYLIE', '33'), ('TINKERBELL', 'KIKI', '34'), ('SPOT', 'JULIA', '35'), ('OREO', 'IVY', '36'), ('GUSSY', 'PEARL', '37'), ('SPENCER', 'POLKA DOT', '38'), ('BUDDY', 'JERRI', '39'), ('JAZZ', 'DEMI', '40'), 453 | ('HERMIE', 'CANDY', '41'), ('JET', 'BELLA', '42'), ('CHOMPER', 'GYPSY', '43'), ('ROSCO', 'FIFI', '44'), ('NACHO', 'LUCY', '45'), ('HONDO', 'PEANUT BUTTER', '46'), ('TORNADO', 'SANDY', '47'), ('BUTTERS', 'BLANCO', '48'), 454 | ('BOB', 'HERSHEY', '49'), ('STOKER', 'DIVA', '50'), ('CHUBBY', 'PARIS', '51'), ('NOVA', 'SOPHIE', '52'), ('PHANTOM', 'DIAMOND', '53'), ('SPIRIT', 'MOCHI', '54'), ('TEX', 'JEMMA', '55'), ('HERBIE', 'ROSIE', '56'), 455 | ('JONAS', 'AMBER', '57'), ('TOBY', 'BUTTERSCOTCH', '58'), ('STANLEY', 'STARLIGHT', '59'), ('AUGGIE', 'BETSY', '60'), ('TEDDY', 'GRACIE', '61'), ('NINJA', 'DUTCHESS', '62'), ('ARNOLD', 'BINDI', '63'), ('COMATOSE', 'DESTINY', '64'), 456 | ('SMOKEY', 'RUBY', '65'), ('PRINCE', 'GABBY', '66'), ('DALTON', 'ABBY', '67'), ('ROMEO', 'SALT', '68'), ('THOR', 'TRIXIE', '69'), ('ECHO', 'BABY', '70'), ('BANDIT', 'PATCHES', '71'), ('MYSTIC', 'CASSIDY', '72'), 457 | ('BALOO', 'SURI', '73'), ('BLAZE', 'ELLA', '74'), ('CHARLIE', 'CINDERELLA', '75'), ('HUMPHREY', 'FLUFFY', '76'), ('DELTA', 'HADLEY', '77'), ('KODO', 'SASSY', '78'), ('KIRBY', 'PENNY', '79'), ('STEWIE', 'BUN BUN', '80'), 458 | ('IGGY', 'ELEANOR', '81'), ('DOBBY', 'DOLLY', '82'), ('LENNY', 'ROXIE', '83'), ('ZIGGY', 'SUZI', '84'), ('MOMO', 'WONDER', '85'), ('FORREST', 'CINDER', '86'), ('GUINNESS', 'CHARM', '87'), ('BRUNO', 'STORM', '88'), 459 | ('HUDINI', 'BETTY', '89'), ('HIP HOP', 'SCARLETT', '90'), ('MAXWELL', 'OPHELIA', '91'), ('YOGI', 'CELIA', '92'), ('HONEY', 'BLONDIE', '93'), ('MILLY', 'ABIGAIL', '94'), ('HAL', 'JADE', '95'), ('DUNCAN', 'SNOW WHITE', '96'), 460 | ('MURPHY', 'ZOEY', '97'), ('SHADOW', 'FARRAH', '98'), ('SCOUT', 'LIQUORICE', '99'), ('KOBIE', 'SUKI', '100') 461 | ) AS Names (Male, Female, Rank); 462 | 463 | -- Colors 464 | CREATE TABLE Reference.Colors 465 | ( 466 | Color VARCHAR(10) NOT NULL PRIMARY KEY 467 | ); 468 | 469 | -- Populate colors 470 | -- Source - Wikipedia (not all 'standard' colors included here) 471 | INSERT INTO Reference.Colors (Color) 472 | VALUES 473 | ('Ginger'), ('Brown'), ('Black'), ('White'), ('Gray'), ('Cream'), 474 | ('Red'), ('Gold'), ('Fawn'), ('Blue'), ('Cinnamon'), ('Beige'), ('Lilach'), ('Opal'); 475 | 476 | -- Common color patterns 477 | -- Source: Wikipedia 478 | CREATE TABLE Reference.Patterns 479 | ( 480 | Species VARCHAR(10) NOT NULL 481 | REFERENCES Reference.Species (Species), 482 | Pattern VARCHAR(20) NOT NULL, 483 | PRIMARY KEY (Species, Pattern), 484 | INDEX NCIDX_Patterns_Pattern(Pattern) 485 | ); 486 | 487 | -- Populate color patterns 488 | -- Source: Wikipedia 489 | INSERT INTO Reference.Patterns (Species, Pattern) 490 | VALUES 491 | ('Cat', 'Solid'), ('Cat', 'Bicolor'), ('Cat', 'Tricolor'), ('Cat', 'Calico'), ('Cat', 'Spotted'), ('Cat', 'Tabby'), ('Cat', 'Tortoiseshell'), 492 | ('Dog', 'Solid'), ('Dog', 'Bicolor'), ('Dog', 'Tricolor'), ('Dog', 'Tuxedo'), ('Dog', 'Spotted'), ('Dog', 'Flecked'), ('Dog', 'Merle'), ('Dog', 'Harlequin'), 493 | ('Rabbit', 'Solid'), ('Rabbit', 'Brindle'), ('Rabbit', 'Broken'), ('Rabbit', 'Marked'), ('Rabbit', 'Ticked'), ('Rabbit', 'Wide Band'), ('Rabbit', 'Shaded'), 494 | ('Ferret', 'Sable'), ('Ferret', 'Albino'), ('Ferret', 'Solid'), 495 | ('Raccoon', 'Bandit Mask'); 496 | 497 | -- Vaccines 498 | -- Source https://www.vetmed.ucdavis.edu/hospital/animal-health-topics/vaccination-guidelines 499 | CREATE TABLE Reference.Vaccines 500 | ( 501 | Vaccine VARCHAR(50) NOT NULL PRIMARY KEY 502 | ); 503 | 504 | INSERT INTO Reference.Vaccines (Vaccine) 505 | VALUES 506 | ('Rabies'), ('Parvovirus'), ('Distemper Virus'), ('Adenovirus'), ('Herpesvirus'), ('Calicivirus'), ('Panleukopenia Virus'), ('Leukemia Virus'), ('Myxomatosis'), ('Viral Haemorrhagic Disease'); 507 | 508 | CREATE TABLE Reference.Species_Vaccines 509 | ( 510 | Species VARCHAR(10) NOT NULL 511 | REFERENCES Reference.Species (Species), 512 | Vaccine VARCHAR(50) NOT NULL 513 | REFERENCES Reference.Vaccines (Vaccine), 514 | PRIMARY KEY (Species, Vaccine), 515 | INDEX NCIDX_FK_Species_Vaccines__Vaccines (Vaccine) 516 | ); 517 | 518 | INSERT INTO Reference.Species_Vaccines (Vaccine, Species) 519 | VALUES 520 | ('Rabies', 'Dog'), ('Parvovirus', 'Dog'), ('Distemper Virus', 'Dog'), ('Adenovirus', 'Dog'), 521 | ('Rabies', 'Cat'), ('Herpesvirus', 'Cat'), ('Calicivirus', 'Cat'), ('Panleukopenia Virus', 'Cat'), ('Leukemia Virus', 'Cat'), 522 | ('Rabies', 'Rabbit'), ('Myxomatosis', 'Rabbit'), ('Viral Haemorrhagic Disease', 'Rabbit'); 523 | 524 | -- States 525 | -- Source: https://simplemaps.com/data/us-cities 526 | -- NOTE: You must download and import the above into a table named US_Cities in a database named US_Cities to run the following queries 527 | 528 | CREATE TABLE Reference.States 529 | ( 530 | State VARCHAR(20) NOT NULL PRIMARY KEY, 531 | State_Code CHAR(2) NOT NULL UNIQUE 532 | ); 533 | 534 | INSERT INTO Reference.States (State, State_Code) 535 | SELECT DISTINCT state_name, 536 | state_id 537 | FROM US_Cities.dbo.us_cities; 538 | 539 | -- Cities 540 | CREATE TABLE Reference.Cities 541 | ( 542 | State VARCHAR(20) NOT NULL 543 | REFERENCES Reference.States (State), 544 | City VARCHAR(30) NOT NULL, 545 | County VARCHAR(30) NOT NULL, 546 | Population INT NOT NULL, 547 | PRIMARY KEY (State, City), 548 | INDEX NCIDX_Cities_City (City) 549 | ); 550 | 551 | -- Populate Cities 552 | -- Source: https://simplemaps.com/data/us-cities 553 | INSERT INTO Reference.Cities (State, City, County, Population) 554 | SELECT state_name, 555 | city, 556 | county_name, 557 | population 558 | FROM US_Cities.dbo.us_cities 559 | WHERE Population >= @Min_Population; -- Limit sample DB only to main cities 560 | 561 | -- City Zip Codes 562 | CREATE TABLE Reference.City_Zip_Codes 563 | ( 564 | State VARCHAR(20) NOT NULL, 565 | City VARCHAR(30) NOT NULL, 566 | CONSTRAINT FK_City_Zip_Codes__Cities 567 | FOREIGN KEY (State, City) 568 | REFERENCES Reference.Cities (State, City), 569 | Zip_Code CHAR(5) NOT NULL 570 | PRIMARY KEY (State, City, Zip_Code), 571 | INDEX NCIDX_City_Zip_Codes_City (City) 572 | ); 573 | 574 | -- Populate Zip Codes 575 | INSERT INTO Reference.City_Zip_Codes (State, City, Zip_Code) 576 | SELECT Source.state_name, 577 | Source.city, 578 | X.value AS Zip_Code 579 | FROM 580 | US_Cities.dbo.us_cities AS Source 581 | CROSS APPLY STRING_SPLIT(Source.zips, ' ') AS X 582 | WHERE EXISTS ( 583 | SELECT NULL 584 | FROM Reference .Cities AS C 585 | WHERE C.City = Source.city 586 | AND 587 | C.State = Source.state_name 588 | ); 589 | 590 | -- Street names 591 | -- Source: https://www.reddit.com/r/dataisbeautiful/comments/2oo23a/the_50_most_popular_street_names_in_the_us_oc/ 592 | CREATE TABLE Reference.Common_Street_Names 593 | ( 594 | [Rank] TINYINT NOT NULL PRIMARY KEY, 595 | Street VARCHAR(20) NOT NULL UNIQUE 596 | ); 597 | 598 | INSERT INTO Reference.Common_Street_Names ([Rank], Street) 599 | VALUES 600 | (1, 'Main'), (2, 'Second'), (3, 'First'), (4, 'Third'), (5, 'Fourth'), (6, 'Fifth'), (7, 'Park'), (8, 'Sixth'), 601 | (9, 'Oak'), (10, 'Seventh'), (11, 'Maple'), (12, 'Pine'), (13, 'Washington'), (14, 'Eighth'), (15, 'Cedar'), (16, 'Elm'), 602 | (17, 'Walnut'), (18, 'Ninth'), (19, 'Tenth'), (20, 'Lake'), (21, 'Sunset'), (22, 'Lincoln'), (23, 'Jackson'), (24, 'Church'), 603 | (25, 'River'), (26, 'Eleventh'), (27, 'Willow'), (28, 'Jefferson'), (29, 'Center'), (30, 'Twelfth'), (31, 'North'), (32, 'Lake view'), 604 | (33, 'Ridge'), (34, 'Hickory'), (35, 'Adams'), (36, 'Cherry'), (37, 'Highland'), (38, 'Johnson'), (39, 'South'), (40, 'Dogwood'), 605 | (41, 'West'), (42, 'Chestnut'), (43, 'Thirteenth'), (44, 'Spruce'), (45, 'Fourteenth'), (46, 'Wilson'), (47, 'Meadow'), (48, 'Forest'), 606 | (49, 'Hill'), (50, 'Madison'); 607 | 608 | -- Integers 609 | CREATE TABLE Reference.Integers 610 | ( 611 | Number INT NOT NULL PRIMARY KEY 612 | ); 613 | 614 | -- Populate with 65536 integers 615 | WITH Level0 616 | AS (SELECT 1 AS constant UNION ALL SELECT 1), 617 | Level1 618 | AS (SELECT 1 AS constant FROM Level0 AS A CROSS JOIN Level0 AS B), 619 | Level2 620 | AS (SELECT 1 AS constant FROM Level1 AS A CROSS JOIN Level1 AS B), 621 | Level3 622 | AS (SELECT 1 AS constant FROM Level2 AS A CROSS JOIN Level2 AS B), 623 | Level4 624 | AS (SELECT 1 AS constant FROM Level3 AS A CROSS JOIN Level3 AS B), 625 | Sequential_Integers 626 | AS (SELECT ROW_NUMBER() OVER (ORDER BY (SELECT NULL)) AS Number FROM Level4) 627 | INSERT INTO Reference.Integers (Number) 628 | SELECT Sequential_Integers.Number 629 | FROM Sequential_Integers; 630 | 631 | -- Fixed federal holidays 632 | -- Source: https://en.wikipedia.org/wiki/Federal_holidays_in_the_United_States 633 | CREATE TABLE Reference.Federal_Holidays_Fixed 634 | ( 635 | Holiday VARCHAR(50) NOT NULL PRIMARY KEY, 636 | Month TINYINT NOT NULL, 637 | Day_of_Month TINYINT NOT NULL 638 | ); 639 | 640 | INSERT INTO Reference.Federal_Holidays_Fixed (Holiday, Month, Day_of_Month) 641 | VALUES 642 | ('New Year''s Day', 1, 1), ('Independence Day', 7, 4), ('Veterans Day', 11, 11), ('Christmas Day', 12, 25); 643 | 644 | -- Floating federal holidays 645 | -- Source: https://en.wikipedia.org/wiki/Federal_holidays_in_the_United_States 646 | CREATE TABLE Reference.Federal_Holidays_Floating 647 | ( 648 | Holiday VARCHAR(50) NOT NULL PRIMARY KEY, 649 | Month TINYINT NOT NULL, 650 | Date_Min TINYINT NOT NULL, 651 | Date_Max TINYINT NOT NULL, 652 | Day_of_Week TINYINT NOT NULL, 653 | ); 654 | 655 | INSERT INTO Reference.Federal_Holidays_Floating (Holiday, Month, Date_Min, Date_Max, Day_of_Week) 656 | VALUES 657 | ('Birthday of Martin Luther King Jr.', 1, 15, 21, 2), ('Washington''s Birthday', 2, 15, 21, 2), ('Memorial Day', 5, 25, 31, 2), ('Labor Day', 9, 1, 7, 2), ('Columbus Day', 10, 8, 14, 2), ('Thanksgiving Day', 11, 22, 28, 5); 658 | 659 | -- Calendar 660 | CREATE TABLE Reference.Calendar 661 | ( 662 | Date DATE NOT NULL PRIMARY KEY, 663 | Year SMALLINT NOT NULL, 664 | Month TINYINT NOT NULL, 665 | Month_Name VARCHAR(10) NOT NULL, 666 | Day TINYINT NOT NULL, 667 | Day_Name VARCHAR(10) NOT NULL, 668 | Day_of_Year SMALLINT NOT NULL, 669 | Weekday TINYINT NOT NULL, 670 | Year_Week TINYINT NOT NULL, 671 | US_Federal_Holiday VARCHAR(50) NULL, 672 | ); 673 | 674 | -- Populate Calendar with dates between @Min_Date_Calendar and @Max_Date_Calendar 675 | INSERT Reference.Calendar (Date, Year, Month, Month_Name, Day, Day_Name, Day_of_Year, Weekday, Year_Week) 676 | SELECT DATEADD(DAY, Number - 1, @Min_Date_Calendar), 677 | YEAR(DATEADD(DAY, Number - 1, @Min_Date_Calendar)), 678 | MONTH(DATEADD(DAY, Number - 1, @Min_Date_Calendar)), 679 | DATENAME(MONTH, (DATEADD(DAY, Number - 1, @Min_Date_Calendar))), 680 | DAY((DATEADD(DAY, Number - 1, @Min_Date_Calendar))), 681 | DATENAME(WEEKDAY, (DATEADD(DAY, Number - 1, @Min_Date_Calendar))), 682 | DATEPART(DAYOFYEAR, (DATEADD(DAY, Number - 1, @Min_Date_Calendar))), 683 | DATEPART(WEEKDAY, (DATEADD(DAY, Number - 1, @Min_Date_Calendar))), 684 | DATEPART(WEEK, (DATEADD(DAY, Number - 1, @Min_Date_Calendar))) 685 | FROM Reference.Integers 686 | WHERE Number <= 1 + DATEDIFF(DAY, @Min_Date_Calendar, @Max_Date_Calendar); 687 | 688 | -- Update fixed holidays 689 | WITH Calendar_Holidays 690 | AS (SELECT C.Date, 691 | C.US_Federal_Holiday, 692 | FHF.Holiday 693 | FROM Reference.Calendar AS C 694 | INNER JOIN 695 | Reference.Federal_Holidays_Fixed AS FHF 696 | ON C.Month = FHF.Month 697 | AND 698 | C.Day = FHF.Day_of_Month 699 | ) 700 | UPDATE Calendar_Holidays 701 | SET Calendar_Holidays.US_Federal_Holiday = Calendar_Holidays.Holiday; 702 | 703 | -- Update floating holidays 704 | WITH Calendar_Holidays 705 | AS (SELECT C.Date, 706 | C.US_Federal_Holiday, 707 | FHF.Holiday 708 | FROM Reference.Calendar AS C 709 | INNER JOIN 710 | Reference.Federal_Holidays_Floating AS FHF 711 | ON C.Month = FHF.Month 712 | AND 713 | C.Day BETWEEN FHF.Date_Min AND FHF.Date_Max 714 | AND 715 | FHF.Day_of_Week = C.Weekday 716 | ) 717 | UPDATE Calendar_Holidays 718 | SET Calendar_Holidays.US_Federal_Holiday = Calendar_Holidays.Holiday; 719 | 720 | ----------------------------------------------------------------- 721 | -- Make reference data read-only except for admins -------------- 722 | -- DENY INSERT, UPDATE, DELETE ON SCHEMA::Reference TO PUBLIC; -- 723 | ----------------------------------------------------------------- 724 | ----------------------------------------------------------------- 725 | --------------------------------------------------------------------------------