create.sql 27.1 KB
1 2 3 4 5 6 7 8 9 10 11 12 13 14 15 16 17 18 19 20 21 22 23 24 25 26 27 28 29 30 31 32 33 34 35 36 37 38 39 40 41 42 43 44 45 46 47 48 49 50 51 52 53 54 55 56 57 58 59 60 61 62 63 64 65 66 67 68 69 70 71 72 73 74 75 76 77 78 79 80 81 82 83 84 85 86 87 88 89 90 91 92 93 94 95 96 97 98 99 100 101 102 103 104 105 106 107 108 109 110 111 112 113 114 115 116 117 118 119 120 121 122 123 124 125 126 127 128 129 130 131 132 133 134 135 136 137 138 139 140 141 142 143 144 145 146 147 148 149 150 151 152 153 154 155 156 157 158 159 160 161 162 163 164 165 166 167 168 169 170 171 172 173 174 175 176 177 178 179 180 181 182 183 184 185 186 187 188 189 190 191 192 193 194 195 196 197 198 199 200 201 202 203 204 205 206 207 208 209 210 211 212 213 214 215 216 217 218 219 220 221 222 223 224 225 226 227 228 229 230 231 232 233 234 235 236 237 238 239 240 241 242 243 244 245 246 247 248 249 250 251 252 253 254 255 256 257 258 259 260 261 262 263 264 265 266 267 268 269 270 271 272 273 274 275 276 277 278 279 280 281 282 283 284 285 286 287 288 289 290 291 292 293 294 295 296 297 298 299 300 301 302 303 304 305 306 307 308 309 310 311 312 313 314 315 316 317 318 319 320 321 322 323 324 325 326 327 328 329 330 331 332 333 334 335 336 337 338 339 340 341 342 343 344 345 346 347 348 349 350 351 352 353 354 355 356 357 358 359 360 361 362 363 364 365 366 367 368 369 370 371 372 373 374 375 376 377 378 379 380 381 382 383 384 385 386 387 388 389 390 391 392 393 394 395 396 397 398 399 400 401 402 403 404 405 406 407 408 409 410 411 412 413 414 415 416 417 418 419 420 421 422 423 424 425 426 427 428 429 430 431 432 433 434 435 436 437 438 439 440 441 442 443 444 445 446 447 448 449 450 451 452 453 454 455 456 457 458 459 460 461 462 463 464 465 466 467 468 469 470 471 472 473 474 475 476 477 478 479 480 481 482 483 484 485 486 487 488 489 490 491 492 493 494 495 496 497 498 499 500 501 502 503 504 505 506 507 508 509 510 511 512 513 514 515 516 517 518 519 520 521 522 523 524 525 526 527 528 529 530 531 532 533 534 535 536 537 538 539 540 541 542 543 544 545 546 547 548 549 550 551 552 553 554 555 556 557 558 559 560 561 562 563 564 565 566 567 568 569 570 571 572 573 574 575 576 577 578 579 580 581 582 583 584 585 586 587 588 589 590 591 592 593 594 595 596 597 598 599 600 601 602 603 604 605 606 607 608 609 610 611 612 613 614 615 616 617 618 619 620 621 622 623 624 625 626 627 628 629 630 631 632 633 634 635 636 637 638 639 640 641 642 643 644 645 646 647 648 649 650 651 652 653 654 655 656 657 658 659 660 661 662 663 664 665 666 667 668 669 670 671 672 673 674 675 676 677 678 679 680 681 682 683 684 685 686 687 688 689 690 691 692 693 694 695 696 697 698 699 700 701 702 703 704 705 706 707 708 709 710 711 712 713 714 715 716 717 718 719 720 721 722 723 724 725 726 727 728 729 730 731 732 733 734 735 736 737 738 739 740 741 742 743 744 745 746 747 748 749 750 751 752 753 754 755 756 757 758 759 760 761 762 763 764 765 766 767 768 769 770 771 772 773 774 775 776 777 778 779 780 781 782 783 784 785 786 787 788 789 790 791 792 793 794 795 796 797 798 799 800 801 802 803 804 805 806 807 808 809 810 811 812 813 814 815 816 817 818 819 820 821 822 823 824 825 826 827 828 829 830 831 832 833 834 835 836 837 838 839 840 841 842 843 844 845 846 847 848 849 850 851 852 853 854 855 856 857 858 859 860 861 862 863 864 865 866 867 868 869 870 871 872 873 874 875 876 877 878 879 880 881 882 883 884 885 886 887 888 889 890 891 892 893 894 895 896 897 898 899 900 901 902 903 904 905 906 907 908 909 910 911 912 913 914 915 916 917 918 919 920 921 922 923 924 925 926 927 928 929 930 931 932 933 934 935 936 937 938 939 940 941 942 943 944 945 946 947 948 949 950 951 952 953 954 955 956 957 958 959 960 961 962 963 964 965 966 967 968 969 970 971 972 973 974 975 976 977 978 979 980 981 982 983 984 985 986 987 988 989 990 991 992 993 994 995 996 997 998 999 1000 1001 1002 1003 1004 1005 1006 1007 1008 1009 1010 1011 1012 1013 1014 1015 1016 1017 1018 1019 1020 1021 1022 1023 1024 1025 1026 1027 1028 1029 1030 1031 1032 1033 1034 1035 1036 1037 1038 1039 1040 1041 1042 1043 1044 1045 1046 1047 1048 1049 1050 1051 1052 1053
DROP DATABASE bilder_new;
DROP USER 'picadmin'@'localhost';

CREATE USER 'picadmin'@'localhost' IDENTIFIED BY '1Rz3ftb.';

--GRANT USAGE ON *.* TO 'picadmin'@ 'localhost' IDENTIFIED BY '********' WITH MAX_QUERIES_PER_HOUR 0 MAX_CONNECTIONS_PER_HOUR 0 MAX_UPDATES_PER_HOUR 0 MAX_USER_CONNECTIONS 0 ;

CREATE DATABASE bilder_new CHARACTER SET utf8 DEFAULT COLLATE utf8_unicode_ci;
GRANT ALL PRIVILEGES ON bilder_new.* TO 'picadmin'@'localhost';

SET storage_engine=InnoDB;
USE bilder_new;

CREATE TABLE language
(
	languageId   BIGINT UNSIGNED NOT NULL auto_increment,
	languageCode VARCHAR(3)      NOT NULL,
	countryCode  VARCHAR(2)      NULL,

	PRIMARY KEY (languageId),
	UNIQUE KEY (languageCode, countryCode)
);

CREATE TABLE i18n
(
	textId   BIGINT UNSIGNED NOT NULL,
	language BIGINT UNSIGNED NOT NULL,
	text     TEXT            NOT NULL,

	PRIMARY KEY (textId, language),
	CONSTRAINT FOREIGN KEY (language)
		REFERENCES language (languageId)
		ON UPDATE CASCADE
		ON DELETE CASCADE
);

CREATE TABLE watermark
(
	watermarkId BIGINT UNSIGNED   NOT NULL auto_increment,
	width       SMALLINT UNSIGNED NOT NULL,
	height      SMALLINT UNSIGNED NOT NULL,
	xpos        SMALLINT          NOT NULL,
	ypos        SMALLINT          NOT NULL,

	PRIMARY KEY (watermarkId)
);

-- Das sollte noch aufgeteilt werden, eine Person kann ein Fotograph, der
-- Besitzer eines Bildes (Copyrighthalter) oder ein user des Bildertools sein.
CREATE TABLE person
(
	personId  BIGINT UNSIGNED NOT NULL auto_increment,
	firstname VARCHAR(30)         NULL,
	surname   VARCHAR(30)         NULL,
	company   VARCHAR(30)         NULL,
	email     VARCHAR(30)         NULL,
	url       VARCHAR(30)         NULL,

	PRIMARY KEY (personId),
	UNIQUE KEY (firstname, surname)
);

CREATE TABLE photographer
(
	photographerId BIGINT UNSIGNED NOT NULL auto_increment,
	personId       BIGINT UNSIGNED NOT NULL,
	cameraId       BIGINT UNSIGNED     NULL,

	PRIMARY KEY (photographerId),
	UNIQUE KEY (personId),
	CONSTRAINT FOREIGN KEY (personId)
		REFERENCES person (personId)
		ON UPDATE CASCADE
		ON DELETE CASCADE 
);

CREATE TABLE owner
(
	ownerId     BIGINT UNSIGNED NOT NULL auto_increment,
	personId    BIGINT UNSIGNED NOT NULL,
	watermarkId BIGINT UNSIGNED     NULL,

	PRIMARY KEY (ownerId),
	UNIQUE KEY (personId),
	CONSTRAINT FOREIGN KEY (personId)
		REFERENCES person (personId)
		ON UPDATE CASCADE
		ON DELETE CASCADE,
	CONSTRAINT FOREIGN KEY (watermarkId)
		REFERENCES watermark (watermarkId)
		ON UPDATE CASCADE
		ON DELETE SET NULL
);

CREATE TABLE format
(
	formatId    BIGINT UNSIGNED   NOT NULL auto_increment,
	width       SMALLINT UNSIGNED NOT NULL,
	height      SMALLINT UNSIGNED NOT NULL,
	quality     TINYINT UNSIGNED  NOT NULL,

	PRIMARY KEY (formatId)
);

CREATE TABLE picture
(
	pictureId      BIGINT UNSIGNED   NOT NULL auto_increment,
	title          BIGINT UNSIGNED       NULL,
	photographerId BIGINT UNSIGNED       NULL,
	ownerId        BIGINT UNSIGNED       NULL,
	origWidth      SMALLINT UNSIGNED NOT NULL,
	origHeight     SMALLINT UNSIGNED NOT NULL,
	trade          ENUM('download',
	                    'buy')       NOT NULL default 'download',
	createDate     TIMESTAMP             NULL DEFAULT CURRENT_TIMESTAMP(),
	`lock`         BOOLEAN           NOT NULL DEFAULT FALSE,

	PRIMARY KEY (pictureId),
	CONSTRAINT FOREIGN KEY (title)
		REFERENCES i18n (textId)
		ON UPDATE CASCADE
		ON DELETE SET NULL,
	CONSTRAINT FOREIGN KEY (photographerId)
		REFERENCES photographer (photographerId)
		ON UPDATE CASCADE
		ON DELETE SET NULL,
	CONSTRAINT FOREIGN KEY (ownerId)
		REFERENCES owner (ownerId)
		ON UPDATE CASCADE
		ON DELETE SET NULL
);

CREATE TABLE pictureDetail
(
	pictureId BIGINT UNSIGNED NOT NULL,
	textId    BIGINT UNSIGNED NOT NULL,
	ident     VARCHAR(30)     NOT NULL DEFAULT "",

	PRIMARY KEY (pictureId, textId),
	UNIQUE KEY (pictureId,ident),
	CONSTRAINT FOREIGN KEY (pictureId)
		REFERENCES picture (pictureId)
		ON UPDATE CASCADE
		ON DELETE CASCADE,
	CONSTRAINT FOREIGN KEY (textId)
		REFERENCES i18n (textId)
		ON UPDATE CASCADE
		ON DELETE CASCADE
);

CREATE TABLE pictureLog
(
	pictureId  BIGINT UNSIGNED NOT NULL,
	`date`     DATE            NOT NULL,
	views      BIGINT UNSIGNED NOT NULL DEFAULT 0,
	downloads  BIGINT UNSIGNED NOT NULL DEFAULT 0,
	downlSize  BIGINT UNSIGNED NOT NULL DEFAULT 0,
	brokeDownl BIGINT UNSIGNED NOT NULL DEFAULT 0,
	brokeSize  BIGINT UNSIGNED NOT NULL DEFAULT 0,

	PRIMARY KEY (pictureId,`date`),
	CONSTRAINT FOREIGN KEY (pictureId)
		REFERENCES picture (pictureId)
		ON UPDATE CASCADE
		ON DELETE CASCADE
);

CREATE TRIGGER picLogDateDefault_t 
BEFORE INSERT ON pictureLog
FOR EACH ROW
	SET NEW.`date` = CURDATE ();

CREATE TABLE picture_format
(
	pictureId BIGINT UNSIGNED NOT NULL,
	formatId  BIGINT UNSIGNED NOT NULL,

	PRIMARY KEY (pictureId,formatId),
	CONSTRAINT FOREIGN KEY (pictureId)
		REFERENCES picture (pictureId)
		ON UPDATE CASCADE
		ON DELETE CASCADE,
	CONSTRAINT FOREIGN KEY (formatId)
		REFERENCES format (formatId)
		ON UPDATE CASCADE
		ON DELETE CASCADE
);

CREATE TABLE location
(
	locationId BIGINT UNSIGNED NOT NULL auto_increment,
	zip        VARCHAR(5)          NULL,
	city       VARCHAR(30)         NULL,
	street     VARCHAR(30)         NULL,
	hno        VARCHAR(5)          NULL,
	name       VARCHAR(30)         NULL,

	PRIMARY KEY (locationId),
	UNIQUE KEY (zip,city,street,hno)
);

CREATE TABLE section
(
	sectionId     BIGINT UNSIGNED  NOT NULL auto_increment,
	title         BIGINT UNSIGNED      NULL,
	locationId    BIGINT UNSIGNED      NULL,
	`lock`        BOOLEAN          NOT NULL DEFAULT FALSE,

	PRIMARY KEY (sectionId),
	CONSTRAINT FOREIGN KEY (title)
		REFERENCES i18n (textId)
		ON UPDATE CASCADE
		ON DELETE SET NULL,
	CONSTRAINT FOREIGN KEY (locationId)
		REFERENCES location (locationId)
		ON UPDATE CASCADE
		ON DELETE SET NULL
);

CREATE TABLE sectionDetail
(
	sectionId BIGINT UNSIGNED NOT NULL,
	textId    BIGINT UNSIGNED NOT NULL,
	ident     VARCHAR(30)     NOT NULL DEFAULT "",

	PRIMARY KEY (sectionId, textId),
	UNIQUE KEY (sectionId,ident),
	CONSTRAINT FOREIGN KEY (sectionId)
		REFERENCES section (sectionId)
		ON UPDATE CASCADE
		ON DELETE CASCADE,
	CONSTRAINT FOREIGN KEY (textId)
		REFERENCES i18n (textId)
		ON UPDATE CASCADE
		ON DELETE CASCADE
);

CREATE TABLE picture_section
(
	pictureId BIGINT UNSIGNED   NOT NULL,
	sectionId BIGINT UNSIGNED   NOT NULL,
	validFrom TIMESTAMP             NULL,
	validTo   TIMESTAMP             NULL,
	prio      SMALLINT UNSIGNED NOT NULL DEFAULT 0,

	PRIMARY KEY (pictureId,sectionId),
	CONSTRAINT FOREIGN KEY (pictureId)
		REFERENCES picture (pictureId)
		ON UPDATE CASCADE
		ON DELETE CASCADE,
	CONSTRAINT FOREIGN KEY (sectionId)
		REFERENCES section (sectionId)
		ON UPDATE CASCADE
		ON DELETE CASCADE
);

CREATE PROCEDURE lockEmptySection (IN oldId BIGINT(20))
	UPDATE section SET `lock` = TRUE
	WHERE
		sectionId IN (
			SELECT sectionId
			FROM picture_section
			INNER JOIN picture USING (pictureId)
			WHERE `lock` = FALSE
			GROUP BY sectionId
			HAVING
				COUNT(*) = 1 AND
				MAX(pictureId) = oldId);

CREATE TRIGGER lockEmptySectionD_t
BEFORE DELETE ON picture
FOR EACH ROW
	CALL lockEmptySection (OLD.pictureId);

CREATE TRIGGER lockEmptySectionU_t
BEFORE UPDATE ON picture
FOR EACH ROW
	CALL lockEmptySection (OLD.pictureId);

CREATE TABLE gallery
(
	galleryId  BIGINT UNSIGNED  NOT NULL auto_increment,
	title      BIGINT UNSIGNED      NULL,
	creator    BIGINT UNSIGNED  NOT NULL,
	createDate TIMESTAMP        NOT NULL DEFAULT CURRENT_TIMESTAMP(),
	`lock`     BOOLEAN          NOT NULL DEFAULT FALSE,

	PRIMARY KEY (galleryId),
	UNIQUE KEY (creator,createDate),
	CONSTRAINT FOREIGN KEY (title)
		REFERENCES i18n (textId)
		ON UPDATE CASCADE
		ON DELETE SET NULL,
	CONSTRAINT FOREIGN KEY (creator)
		REFERENCES person (personId)
		ON UPDATE CASCADE
);

CREATE TABLE galleryDetail
(
	galleryId BIGINT UNSIGNED NOT NULL,
	textId    BIGINT UNSIGNED NOT NULL,
	ident     VARCHAR(30)     NOT NULL DEFAULT "",

	PRIMARY KEY (galleryId, textId),
	UNIQUE KEY (galleryId,ident),
	CONSTRAINT FOREIGN KEY (galleryId)
		REFERENCES gallery (galleryId)
		ON UPDATE CASCADE
		ON DELETE CASCADE,
	CONSTRAINT FOREIGN KEY (textId)
		REFERENCES i18n (textId)
		ON UPDATE CASCADE
		ON DELETE CASCADE
);

CREATE TABLE section_gallery
(
	sectionId BIGINT UNSIGNED   NOT NULL,
	galleryId BIGINT UNSIGNED   NOT NULL,
	validFrom TIMESTAMP             NULL,
	validTo   TIMESTAMP             NULL,
	prio      SMALLINT UNSIGNED NOT NULL DEFAULT 0,

	PRIMARY KEY (sectionId,galleryId),
	CONSTRAINT FOREIGN KEY (sectionId)
		REFERENCES section (sectionId)
		ON UPDATE CASCADE
		ON DELETE CASCADE,
	CONSTRAINT FOREIGN KEY (galleryId)
		REFERENCES gallery (galleryId)
		ON UPDATE CASCADE
		ON DELETE CASCADE
);

CREATE PROCEDURE lockEmptyGallery (IN oldId BIGINT(20))
	UPDATE gallery SET `lock` = TRUE
	WHERE
		galleryId IN (
			SELECT galleryId
			FROM section_gallery
			INNER JOIN section USING (sectionId)
			WHERE `lock` = FALSE
			GROUP BY galleryId
			HAVING
				COUNT(*) = 1 AND
				MAX(sectionId) = oldId);

CREATE TRIGGER lockEmptyGalleryD_t
BEFORE DELETE ON section
FOR EACH ROW
	CALL lockEmptyGallery (OLD.sectionId);

CREATE TRIGGER lockEmptyGalleryU_t
BEFORE UPDATE ON section
FOR EACH ROW
	CALL lockEmptyGallery (OLD.sectionId);

CREATE TABLE template
(
	templateId BIGINT UNSIGNED NOT NULL auto_increment,
	name       VARCHAR(100)    NOT NULL,

	PRIMARY KEY (templateId),
	UNIQUE KEY (name)
);

CREATE TABLE category
(
	categoryId  BIGINT UNSIGNED  NOT NULL auto_increment,
	title       BIGINT UNSIGNED      NULL,
	templateId  BIGINT UNSIGNED  NOT NULL,
	`lock`      BOOLEAN          NOT NULL DEFAULT FALSE,

	PRIMARY KEY (categoryId),
	CONSTRAINT FOREIGN KEY (title)
		REFERENCES i18n (textId)
		ON UPDATE CASCADE
		ON DELETE SET NULL,
	CONSTRAINT FOREIGN KEY (templateId)
		REFERENCES template (templateId)
		ON UPDATE CASCADE
);

CREATE TABLE categoryDetail
(
	categoryId BIGINT UNSIGNED NOT NULL,
	textId     BIGINT UNSIGNED NOT NULL,
	ident      VARCHAR(30)     NOT NULL DEFAULT "",

	PRIMARY KEY (categoryId, textId),
	UNIQUE KEY (categoryId,ident),
	CONSTRAINT FOREIGN KEY (categoryId)
		REFERENCES category (categoryId)
		ON UPDATE CASCADE
		ON DELETE CASCADE,
	CONSTRAINT FOREIGN KEY (textId)
		REFERENCES i18n (textId)
		ON UPDATE CASCADE
		ON DELETE CASCADE
);

CREATE TABLE gallery_category
(
	galleryId   BIGINT UNSIGNED   NOT NULL,
	categoryId  BIGINT UNSIGNED   NOT NULL,
	validFrom   TIMESTAMP             NULL,
	validTo     TIMESTAMP             NULL,
	prio        SMALLINT UNSIGNED NOT NULL DEFAULT 0,

	PRIMARY KEY (galleryId,categoryId),
	CONSTRAINT FOREIGN KEY (galleryId)
		REFERENCES gallery (galleryId)
		ON UPDATE CASCADE
		ON DELETE CASCADE,
	CONSTRAINT FOREIGN KEY (categoryId)
		REFERENCES category (categoryId)
		ON UPDATE CASCADE
		ON DELETE CASCADE
);

CREATE TABLE subCategory
(
	categoryId BIGINT UNSIGNED NOT NULL,
	subId      BIGINT UNSIGNED NOT NULL,

	PRIMARY KEY (categoryId,subId),
	CONSTRAINT FOREIGN KEY (categoryId)
		REFERENCES category (categoryId)
		ON UPDATE CASCADE
		ON DELETE CASCADE,
	CONSTRAINT FOREIGN KEY (subId)
		REFERENCES category (categoryId)
		ON UPDATE CASCADE
		ON DELETE CASCADE
);

CREATE VIEW i18nView AS
	SELECT
		textId, languageCode, countryCode, text
	FROM i18n _1
		INNER JOIN language ON language = languageId;

DELIMITER //
CREATE FUNCTION gettextFunc (tId BIGINT(20))
RETURNS TEXT
READS SQL DATA
COMMENT 'This function nees the Variable @LANG set to the current locale.'
BEGIN
	DECLARE lText TEXT;
	DECLARE lc VARCHAR(3);
	DECLARE cc VARCHAR(2);

	SET lc = SUBSTRING(@LANG, 1,
		CASE LOCATE('_', @LANG)
			WHEN 0 THEN CHAR_LENGTH(@LANG)
			ELSE LOCATE('_', @LANG)-1
		END);
	SET lc = CASE WHEN lc IS NOT NULL THEN lc ELSE 'en' END;

	SET cc = SUBSTR(@LANG,
		CASE LOCATE('_', @LANG)
			WHEN 0 THEN NULL
			ELSE LOCATE('_', @LANG)+1
		END);

	SELECT `text` INTO lText
	FROM i18nView
	WHERE
		textId = tId AND
		languageCode = lc AND
		countryCode = cc;
	IF lText IS NULL THEN
			SELECT `text` INTO lText
			FROM i18nView
			WHERE
				textId = tId AND
				languageCode = lc AND
				countryCode IS NULL;
	END If;
	IF lText IS NULL THEN
			SELECT `text` INTO lText
			FROM i18nView
			WHERE
				textId = tId AND
				languageCode = 'en' AND
				countryCode IS NULL ;
	END If;

	RETURN lText;
END//
DELIMITER ;

CREATE VIEW personsView AS
	SELECT
		personId, photographerId, ownerId,
		firstname, surname, company, email, url, cameraId,
		width AS wmWidth, height AS wmHeight, xpos AS wmXPos, ypos AS wmYPos
	FROM person 
		LEFT JOIN photographer USING (personId)
		LEFT JOIN owner USING (personId)
		LEFT JOIN watermark USING (watermarkId);

CREATE VIEW photographerView AS
	SELECT
		photographerId,
		firstname AS pFirstname, surname AS pSurname, company AS pCompany,
		email AS pEmail, url AS pUrl, cameraId
	FROM photographer
		LEFT JOIN person USING (personId);

CREATE VIEW ownerView AS
	SELECT
		ownerId,
		firstname AS oFirstname, surname AS oSurname, company AS oCompany,
		email AS oEmail, url AS oUrl,
		width AS wmWidth, height AS wmHeight, xpos AS wmXPos, ypos AS wmYPos
	FROM owner
		LEFT JOIN person USING (personId)
		LEFT JOIN watermark USING (watermarkId);

CREATE VIEW picturesView AS
	SELECT
		_1.pictureId,
		gettextFunc(title) AS pTitle,
		gettextFunc(textId) AS pDetails, ident AS pDetailIdent,
		pFirstname, pSurname, pCompany, pEmail, pUrl, cameraId,
		oFirstname, oSurname, oCompany, oEmail, oUrl,
		wmWidth, wmHeight, wmXPos, wmYPos,
		origWidth, origHeight, trade, createDate AS pCreateDate,
		width, height, quality,
		`date` AS vDate, views, downloads, downlSize, brokeDownl, brokeSize
	FROM picture _1
		LEFT JOIN pictureDetail USING (pictureId)
		LEFT JOIN photographerView USING (photographerId)
		LEFT JOIN ownerView USING (ownerId)
		LEFT JOIN pictureLog USING (pictureId)
		INNER JOIN picture_format _2 ON
			_1.pictureId = _2.pictureId AND
			_1.`lock` = FALSE
		INNER JOIN format USING (formatId);

CREATE VIEW pictureCountsSumView AS
	SELECT
		pictureId, pTitle, pDetails, pDetailIdent,
		pFirstname, pSurname, pCompany, pEmail, pUrl, cameraId,
		oFirstname, oSurname, oCompany, oEmail, oUrl, 
		wmWidth, wmHeight, wmXPos, wmYPos,
		origWidth, origHeight, trade, pCreateDate, width, height, quality,
		CAST(SUM(views) AS UNSIGNED) AS views,
		CAST(SUM(downloads) AS UNSIGNED) AS downloads, 
		CAST(SUM(downlSize) AS UNSIGNED) AS downlSize,
		CAST(SUM(brokeDownl) AS UNSIGNED) AS brokeDownl, 
		CAST(SUM(brokeSize) AS UNSIGNED) AS brokeSize
	FROM picturesView
	GROUP BY
		pictureId, pTitle, pDetails, pDetailIdent,
		pCreateDate, origWidth, origHeight, trade, width, height, quality,
		pFirstname, pSurname, pCompany, pEmail, pUrl, cameraId,
		oFirstname, oSurname, oCompany, oEmail, oUrl, 
		wmWidth, wmHeight, wmXPos, wmYPos;

CREATE VIEW sectionsView AS
	SELECT
		sectionId, gettextFunc(title) AS sTitle,
		gettextFunc(_3.textId) AS sDetails, _3.ident AS sDetailIdent,
		zip, city, street, hno
	FROM section _1
		LEFT JOIN location _2 USING (locationId)
		LEFT JOIN sectionDetail _3 USING (sectionId)
	WHERE
		_1.`lock` = FALSE;

CREATE VIEW sectionPicturesView AS
	SELECT
		sectionId, sTitle, sDetails, sDetailIdent,
		zip, city, street, hno,
		pictureId, pTitle, pDetails, pDetailIdent,
		pFirstname, pSurname, pCompany, pEmail, pUrl, cameraId,
		oFirstname, oSurname, oCompany, oEmail, oUrl, 
		wmWidth, wmHeight, wmXPos, wmYPos,
		origWidth, origHeight, trade, pCreateDate, width, height, quality,
		vDate, views, downloads, downlSize, brokeDownl, brokeSize
	FROM sectionsView
		INNER JOIN picture_section USING (sectionId)
		INNER JOIN picturesView USING (pictureId);

CREATE VIEW sectionCountsView AS
	SELECT
		sectionId, sTitle, sDetails, sDetailIdent,
		zip, city, street, hno, vDate,
		CAST(SUM(views) AS UNSIGNED) AS views,
		CAST(SUM(downloads) AS UNSIGNED) AS downloads, 
		CAST(SUM(downlSize) AS UNSIGNED) AS downlSize,
		CAST(SUM(brokeDownl) AS UNSIGNED) AS brokeDownl, 
		CAST(SUM(brokeSize) AS UNSIGNED) AS brokeSize
	FROM sectionPicturesView
	GROUP BY
		sectionId, sTitle, sDetails, sDetailIdent,
		zip, city, street, hno, vDate;

CREATE VIEW sectionCountsSumView AS
	SELECT
		sectionId, sTitle, sDetails, sDetailIdent,
		zip, city, street, hno,
		CAST(SUM(views) AS UNSIGNED) AS views,
		CAST(SUM(downloads) AS UNSIGNED) AS downloads, 
		CAST(SUM(downlSize) AS UNSIGNED) AS downlSize,
		CAST(SUM(brokeDownl) AS UNSIGNED) AS brokeDownl, 
		CAST(SUM(brokeSize) AS UNSIGNED) AS brokeSize
	FROM sectionPicturesView
	GROUP BY
		sectionId, sTitle, sDetails, sDetailIdent,
		zip, city, street, hno;

CREATE VIEW galleriesView AS
	SELECT
		galleryId,
		gettextFunc(title) AS gTitle,
		gettextFunc(_4.textId) AS gDetails, _4.ident AS gDetailIdent,
		createDate AS sCreateDate,
		creator, firstname AS cFirstname, surname AS cSurname, 
		company AS cCompany, email AS cEmail, url AS cUrl
	FROM gallery _1
		INNER JOIN person _2 ON
			_1.creator = _2.personId AND
			_1.`lock` = FALSE
		LEFT JOIN galleryDetail _4 USING (galleryId);

CREATE VIEW galleryPicturesView AS
	SELECT
		galleryId, gTitle, gDetails, gDetailIdent,
		sCreateDate, creator, cFirstname, cSurname, cCompany, cEmail, cUrl,
		sectionId, sTitle, sDetails, sDetailIdent,
		zip, city, street, hno,
		pictureId, pTitle, pDetails, pDetailIdent,
		pFirstname, pSurname, pCompany, pEmail, pUrl, cameraId,
		oFirstname, oSurname, oCompany, oEmail, oUrl, 
		wmWidth, wmHeight, wmXPos, wmYPos,
		origWidth, origHeight, trade, pCreateDate, width, height, quality,
		vDate, views, downloads, downlSize, brokeDownl, brokeSize
	FROM galleriesView _1
		INNER JOIN section_gallery _2 USING (galleryId)
		INNER JOIN sectionPicturesView _3 USING (sectionId);

CREATE VIEW galleryCountsView AS
	SELECT
		galleryId, gTitle, gDetails, gDetailIdent, sCreateDate,
		creator, cFirstname, cSurname, cCompany, cEmail, cUrl, vDate,
		CAST(SUM(views) AS UNSIGNED) AS views,
		CAST(SUM(downloads) AS UNSIGNED) AS downloads, 
		CAST(SUM(downlSize) AS UNSIGNED) AS downlSize,
		CAST(SUM(brokeDownl) AS UNSIGNED) AS brokeDownl, 
		CAST(SUM(brokeSize) AS UNSIGNED) AS brokeSize
	FROM galleryPicturesView
	GROUP BY
		galleryId, gTitle, gDetails, gDetailIdent, sCreateDate,
		creator, cFirstname, cSurname, cCompany, cEmail, cUrl, vDate;

CREATE VIEW galleryCountsSumView AS
	SELECT
		galleryId, gTitle, gDetails, gDetailIdent, sCreateDate,
		creator, cFirstname, cSurname, cCompany, cEmail, cUrl,
		CAST(SUM(views) AS UNSIGNED) AS views,
		CAST(SUM(downloads) AS UNSIGNED) AS downloads, 
		CAST(SUM(downlSize) AS UNSIGNED) AS downlSize,
		CAST(SUM(brokeDownl) AS UNSIGNED) AS brokeDownl, 
		CAST(SUM(brokeSize) AS UNSIGNED) AS brokeSize
	FROM galleryPicturesView
	GROUP BY
		galleryId, gTitle, gDetails, gDetailIdent, sCreateDate,
		creator, cFirstname, cSurname, cCompany, cEmail, cUrl;

CREATE VIEW gallerySectionsView AS
	SELECT
		galleryId, gTitle, gDetails, gDetailIdent,
		sCreateDate, creator, cFirstname, cSurname, cCompany, cEmail, cUrl,
		sectionId, sTitle, sDetails, sDetailIdent,
		zip, city, street, hno
	FROM galleriesView _1
		INNER JOIN section_gallery _2 USING (galleryId)
		INNER JOIN sectionsView _3 USING (sectionId);

CREATE VIEW categoriesView AS
	SELECT
		categoryId,
		gettextFunc(title) AS cTitle,
		gettextFunc(_5.textId) AS cDetails, _5.ident AS cDetailIdent,
		_2.templateId, _2.name AS templateName,
		_4.subId
	FROM category _1
		INNER JOIN template _2 ON
			_1.templateId = _2.templateId AND
			_1.`lock` = FALSE
		LEFT JOIN categoryDetail _5 USING (categoryId)
		LEFT JOIN subCategory _4 USING (categoryId);

CREATE VIEW catPicturesView AS
	SELECT
		categoryId, cTitle, cDetails, cDetailIdent,
		templateId, templateName, subId,
		galleryId, gTitle, gDetails, gDetailIdent,
		sCreateDate, creator, cFirstname, cSurname, cCompany, cEmail, cUrl,
		sectionId, sTitle, sDetails, sDetailIdent,
		zip, city, street, hno,
		pictureId, pTitle, pDetails, pDetailIdent,
		origWidth, origHeight, trade, pCreateDate, width, height, quality,
		pFirstname, pSurname, pCompany, pEmail, pUrl, cameraId,
		oFirstname, oSurname, oCompany, oEmail, oUrl, 
		wmWidth, wmHeight, wmXPos, wmYPos,
		vDate, views, downloads, downlSize, brokeDownl, brokeSize
	FROM categoriesView
		INNER JOIN gallery_category USING (categoryId)
		INNER JOIN galleryPicturesView USING (galleryId);
		
CREATE VIEW categoryCountsView AS
	SELECT
		categoryId, cTitle, cDetails, cDetailIdent,
		templateId, templateName, subId, vDate,
		CAST(SUM(views) AS UNSIGNED) AS views,
		CAST(SUM(downloads) AS UNSIGNED) AS downloads, 
		CAST(SUM(downlSize) AS UNSIGNED) AS downlSize,
		CAST(SUM(brokeDownl) AS UNSIGNED) AS brokeDownl, 
		CAST(SUM(brokeSize) AS UNSIGNED) AS brokeSize
	FROM catPicturesView
	GROUP BY
		categoryId, cTitle, cDetails, cDetailIdent,
		templateId, templateName, subId, vDate;

CREATE VIEW categoryCountsSumView AS
	SELECT
		categoryId, cTitle, cDetails, cDetailIdent,
		templateId, templateName, subId,
		CAST(SUM(views) AS UNSIGNED) AS views,
		CAST(SUM(downloads) AS UNSIGNED) AS downloads, 
		CAST(SUM(downlSize) AS UNSIGNED) AS downlSize,
		CAST(SUM(brokeDownl) AS UNSIGNED) AS brokeDownl, 
		CAST(SUM(brokeSize) AS UNSIGNED) AS brokeSize
	FROM catPicturesView
	GROUP BY
		categoryId, cTitle, cDetails, cDetailIdent,
		templateId, templateName, subId;

CREATE VIEW catSectionsView AS
	SELECT
		categoryId, cTitle, cDetails, cDetailIdent,
		templateId, templateName, subId,
		galleryId, gTitle, gDetails, gDetailIdent,
		sCreateDate, creator, cFirstname, cSurname, cCompany, cEmail, cUrl,
		sectionId, sTitle, sDetails, sDetailIdent,
		zip, city, street, hno
	FROM categoriesView
		INNER JOIN gallery_category USING (categoryId)
		INNER JOIN gallerySectionsView USING (galleryId);

CREATE VIEW catGalleriesView AS
	SELECT
		categoryId, cTitle, cDetails, cDetailIdent,
		templateId, templateName, subId,
		galleryId, gTitle, gDetails, gDetailIdent,
		sCreateDate, creator, cFirstname, cSurname, cCompany, cEmail, cUrl
	FROM categoriesView
		INNER JOIN gallery_category USING (categoryId)
		INNER JOIN galleriesView USING (galleryId);

DELIMITER //
CREATE PROCEDURE updateOwner (IN pid BIGINT,
	IN _width SMALLINT UNSIGNED, IN _height SMALLINT UNSIGNED, 
	IN _xpos SMALLINT, IN _ypos SMALLINT)
BEGIN
	DECLARE wid, oid BIGINT DEFAULT NULL;

	IF _width IS NOT NULL AND _height IS NOT NULL AND
		_xpos IS NOT NULL AND _ypos IS NOT NULL
	THEN
		SELECT ownerId, watermarkId INTO oid, wid
		FROM owner
		WHERE personId = pid;

		IF oid IS NULL
		THEN
			SELECT watermarkId INTO wid
			FROM watermark
			WHERE
				height = _height AND
				width = _width AND
				xpos = _xpos AND
				ypos = _ypos;

			IF wid IS NULL
			THEN
				INSERT INTO watermark (width, height, xpos, ypos)
				VALUES (_width, _height, _xpos, _ypos);
				SELECT LAST_INSERT_ID() INTO wid;
			END IF;

			INSERT INTO owner (personId, watermarkId)
			VALUES (pid, wid);
		ELSE
			IF wid IS NULL
			THEN
				INSERT INTO watermark (width, height, xpos, ypos)
				VALUES (_width, _height, _xpos, _ypos);
				SELECT LAST_INSERT_ID() INTO wid;
			ELSE
				UPDATE watermark
				SET
					width = _width,
					height = _height,
					xpos = _xpos,
					ypos = _ypos
				WHERE watermarkId = wid;
			END IF;

			UPDATE owner
			SET watermarkId = wid
			WHERE ownerId = oid;
		END IF;
	END IF;

	SELECT oid, wid;
END//
DELIMITER ;

DELIMITER //
CREATE PROCEDURE updatePhotographer (IN pid BIGINT, IN _camId BIGINT)
BEGIN
	DECLARE phid BIGINT DEFAULT NULL;

	IF _camId IS NOT NULL
	THEN
		SELECT photographerId INTO phid
		FROM photographer
		WHERE personId = pid;

		IF phid IS NULL
		THEN
			INSERT INTO photographer (personId, cameraId)
			VALUES (pid, _camId);
			SELECT LAST_INSERT_ID() INTO phid;
		ELSE
			UPDATE photographer
			SET cameraId = _camId
			WHERE photographerId = phid;
		END IF;
	END IF;

	SELECT phid;
END//
DELIMITER ;

DELIMITER //
CREATE PROCEDURE updatePerson (IN _firstname VARCHAR(30),
	IN _surname VARCHAR(30), IN _company VARCHAR(30), IN _email VARCHAR(30),
	IN _url VARCHAR(30), IN _camId BIGINT,
	IN _width SMALLINT UNSIGNED, IN _height SMALLINT UNSIGNED, 
	IN _xpos SMALLINT, IN _ypos SMALLINT)
BEGIN
	DECLARE pid BIGINT DEFAULT NULL;

	IF _firstname IS NOT NULL AND _surname IS NOT NULL
	THEN
		SELECT personId INTO pid
		FROM person
		WHERE 
			UPPER(firstname) = UPPER(_firstname) AND
			UPPER(surname) = UPPER(_surname);

		IF pid IS NOT NULL
		THEN
			UPDATE person
			SET
				firstname = _firstname,
				surname = _surname,
				company = _company,
				email = _email,
				url = _url
			WHERE
				personId = pid;
		ELSE
			INSERT INTO person (firstname, surname, company, email, url)
			VALUES (_firstname, _surname, _company, _email, _url);
			SELECT LAST_INSERT_ID() INTO pid;
		END IF;

		CALL updateOwner (pid, _width, _height, _xpos, _ypos);
		CALL updatePhotographer (pid, _camId);
	END IF;

	SELECT pid;
END//
DELIMITER ;

INSERT INTO language
	(languageCode, countryCode)
VALUES
	('de', NULL),
	('de', 'DE'),
	('en', NULL),
	('en', 'GB'),
	('en', 'US');

INSERT INTO person
	(firstname, surname)
VALUES
	('Elisabeth', 'Steffers'),
	('Mechtild', 'Steffers'),
	('Wilhelm', 'Steffers'),
	('Markus', 'Engbers'),
	('Jens', 'Rautenberg'),
	('Achim', 'Krämer'),
	('Lambert', 'Herrgesell'),
	('Jochen', 'Bilek'),
	('Holger', 'Böking'),
	('Torsten', 'Böking'),
	('Georg', 'Steffers'),
	('Donald', 'von Entenhausen'),
	('Dagobert', 'von Entenhausen');

INSERT INTO watermark
	(width, height, xpos, ypos)
VALUES
	(22, 22, -5, -5);

INSERT INTO photographer
	(personId, cameraId)
VALUES
	(2, 3);

INSERT INTO owner
	(personId, watermarkId)
VALUES
	(1, 1),
	(2, 1);

INSERT INTO i18n
	(textId, language, text)
VALUES
	(1, 1, 'Das erste Bild'),
	(1, 2, 'Das erste Bild'),
	(1, 3, 'The first picture'),
	(2, 1, 'Der erste Testeintrag in der DB'),
	(2, 2, 'Der erste Testeintrag in der DB'),
	(2, 3, 'The first testentry in the DB'),
	(3, 1, 'Pictures von Zuhause'),
	(3, 2, 'Pictures von Zuhause'),
	(3, 3, 'Pictures from home'),
	(4, 1, 'So wohn ich nunmal und basta.'),
	(4, 2, 'So wohn ich nunmal und basta.'),
	(4, 3, 'That\'s the way i live. End of story.'),
	(5, 1, 'Daheim'),
	(5, 3, 'Home'),
	(6, 1, 'Diese Sektion zeigt mein Zuhause'),
	(6, 3, 'This section shows my home'),
	(7, 1, 'dummy'),
	(7, 3, 'dummy'),
	(8, 1, 'Eine Dummy-Sektion'),
	(8, 3, 'A dummy-section'),
	(9, 1, 'Galerie 1'),
	(9, 3, 'Gallery 1'),
	(10, 1, 'Die erste Galerie'),
	(10, 3, 'The first gallery'),
	(11, 1, 'Kategorie 1'),
	(11, 3, 'Category 1'),
	(12, 1, 'Die erste Kategorie'),
	(12, 3, 'The first category');

INSERT INTO format
	(width, height, quality)
VALUES
	(1024, 768, 100),
	(800, 600, 100);

INSERT INTO picture
	(title, photographerId, ownerId, origWidth, origHeight)
VALUES
	(1, 1, 2, 2835, 1212),
	(3, 1, 1, 2135, 1100),
	(1, 1, 2, 1024, 915);

INSERT INTO pictureDetail
	(pictureId, textId)
VALUES
	(1, 2),
	(2, 4),
	(3, 2);

INSERT INTO picture_format
	(pictureId, formatId)
VALUES
	(1, 1),
	(1, 2),
	(2, 1),
	(3, 1);

INSERT INTO location
	(zip, city, street, hno, name)
VALUES
	('48145', 'Münster', 'Warendorfer Str.', '75', 'Daheim');

INSERT INTO section
	(title, locationId)
VALUES
	(5, 1),
	(7, 1);

INSERT INTO sectionDetail
	(sectionId, textId)
VALUES
	(1, 6),
	(2, 8);

INSERT INTO picture_section
	(pictureId, sectionId, prio)
VALUES
	(1, 1, 1),
	(2, 1, 1),
	(1, 2, 1);

INSERT INTO gallery
	(title, creator)
VALUES
	(9, 1);

INSERT INTO galleryDetail
	(galleryId, textId)
VALUES
	(1, 10);

INSERT INTO section_gallery
	(sectionId, galleryId, prio)
VALUES
	(1, 1, 1);

INSERT INTO template
	(templateId, name)
VALUES
	(1, 'Template 1');

INSERT INTO category
	(title, templateId)
VALUES
	(11, 1);

INSERT INTO categoryDetail
	(categoryId, textId)
VALUES
	(1, 12);

INSERT INTO gallery_category
	(galleryId, categoryId, prio)
VALUES
	(1, 1, 1);