forked from devrimgunduz/pagila
-
Notifications
You must be signed in to change notification settings - Fork 0
/
pagila-schema.sql
1827 lines (1255 loc) · 51.2 KB
/
pagila-schema.sql
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
--
-- PostgreSQL database dump
--
-- Dumped from database version 13beta3
-- Dumped by pg_dump version 13beta3
SET statement_timeout = 0;
SET lock_timeout = 0;
SET idle_in_transaction_session_timeout = 0;
SET client_encoding = 'UTF8';
SET standard_conforming_strings = on;
SELECT pg_catalog.set_config('search_path', '', false);
SET check_function_bodies = false;
SET xmloption = content;
SET client_min_messages = warning;
SET row_security = off;
--
-- Name: mpaa_rating; Type: TYPE; Schema: public; Owner: postgres
--
CREATE TYPE public.mpaa_rating AS ENUM (
'G',
'PG',
'PG-13',
'R',
'NC-17'
);
ALTER TYPE public.mpaa_rating OWNER TO postgres;
--
-- Name: year; Type: DOMAIN; Schema: public; Owner: postgres
--
CREATE DOMAIN public.year AS integer
CONSTRAINT year_check CHECK (((VALUE >= 1901) AND (VALUE <= 2155)));
ALTER DOMAIN public.year OWNER TO postgres;
--
-- Name: _group_concat(text, text); Type: FUNCTION; Schema: public; Owner: postgres
--
CREATE FUNCTION public._group_concat(text, text) RETURNS text
LANGUAGE sql IMMUTABLE
AS $_$
SELECT CASE
WHEN $2 IS NULL THEN $1
WHEN $1 IS NULL THEN $2
ELSE $1 || ', ' || $2
END
$_$;
ALTER FUNCTION public._group_concat(text, text) OWNER TO postgres;
--
-- Name: film_in_stock(integer, integer); Type: FUNCTION; Schema: public; Owner: postgres
--
CREATE FUNCTION public.film_in_stock(p_film_id integer, p_store_id integer, OUT p_film_count integer) RETURNS SETOF integer
LANGUAGE sql
AS $_$
SELECT inventory_id
FROM inventory
WHERE film_id = $1
AND store_id = $2
AND inventory_in_stock(inventory_id);
$_$;
ALTER FUNCTION public.film_in_stock(p_film_id integer, p_store_id integer, OUT p_film_count integer) OWNER TO postgres;
--
-- Name: film_not_in_stock(integer, integer); Type: FUNCTION; Schema: public; Owner: postgres
--
CREATE FUNCTION public.film_not_in_stock(p_film_id integer, p_store_id integer, OUT p_film_count integer) RETURNS SETOF integer
LANGUAGE sql
AS $_$
SELECT inventory_id
FROM inventory
WHERE film_id = $1
AND store_id = $2
AND NOT inventory_in_stock(inventory_id);
$_$;
ALTER FUNCTION public.film_not_in_stock(p_film_id integer, p_store_id integer, OUT p_film_count integer) OWNER TO postgres;
--
-- Name: get_customer_balance(integer, timestamp with time zone); Type: FUNCTION; Schema: public; Owner: postgres
--
CREATE FUNCTION public.get_customer_balance(p_customer_id integer, p_effective_date timestamp with time zone) RETURNS numeric
LANGUAGE plpgsql
AS $$
--#OK, WE NEED TO CALCULATE THE CURRENT BALANCE GIVEN A CUSTOMER_ID AND A DATE
--#THAT WE WANT THE BALANCE TO BE EFFECTIVE FOR. THE BALANCE IS:
--# 1) RENTAL FEES FOR ALL PREVIOUS RENTALS
--# 2) ONE DOLLAR FOR EVERY DAY THE PREVIOUS RENTALS ARE OVERDUE
--# 3) IF A FILM IS MORE THAN RENTAL_DURATION * 2 OVERDUE, CHARGE THE REPLACEMENT_COST
--# 4) SUBTRACT ALL PAYMENTS MADE BEFORE THE DATE SPECIFIED
DECLARE
v_rentfees DECIMAL(5,2); --#FEES PAID TO RENT THE VIDEOS INITIALLY
v_overfees INTEGER; --#LATE FEES FOR PRIOR RENTALS
v_payments DECIMAL(5,2); --#SUM OF PAYMENTS MADE PREVIOUSLY
BEGIN
SELECT COALESCE(SUM(film.rental_rate),0) INTO v_rentfees
FROM film, inventory, rental
WHERE film.film_id = inventory.film_id
AND inventory.inventory_id = rental.inventory_id
AND rental.rental_date <= p_effective_date
AND rental.customer_id = p_customer_id;
SELECT COALESCE(SUM(IF((rental.return_date - rental.rental_date) > (film.rental_duration * '1 day'::interval),
((rental.return_date - rental.rental_date) - (film.rental_duration * '1 day'::interval)),0)),0) INTO v_overfees
FROM rental, inventory, film
WHERE film.film_id = inventory.film_id
AND inventory.inventory_id = rental.inventory_id
AND rental.rental_date <= p_effective_date
AND rental.customer_id = p_customer_id;
SELECT COALESCE(SUM(payment.amount),0) INTO v_payments
FROM payment
WHERE payment.payment_date <= p_effective_date
AND payment.customer_id = p_customer_id;
RETURN v_rentfees + v_overfees - v_payments;
END
$$;
ALTER FUNCTION public.get_customer_balance(p_customer_id integer, p_effective_date timestamp with time zone) OWNER TO postgres;
--
-- Name: inventory_held_by_customer(integer); Type: FUNCTION; Schema: public; Owner: postgres
--
CREATE FUNCTION public.inventory_held_by_customer(p_inventory_id integer) RETURNS integer
LANGUAGE plpgsql
AS $$
DECLARE
v_customer_id INTEGER;
BEGIN
SELECT customer_id INTO v_customer_id
FROM rental
WHERE return_date IS NULL
AND inventory_id = p_inventory_id;
RETURN v_customer_id;
END $$;
ALTER FUNCTION public.inventory_held_by_customer(p_inventory_id integer) OWNER TO postgres;
--
-- Name: inventory_in_stock(integer); Type: FUNCTION; Schema: public; Owner: postgres
--
CREATE FUNCTION public.inventory_in_stock(p_inventory_id integer) RETURNS boolean
LANGUAGE plpgsql
AS $$
DECLARE
v_rentals INTEGER;
v_out INTEGER;
BEGIN
-- AN ITEM IS IN-STOCK IF THERE ARE EITHER NO ROWS IN THE rental TABLE
-- FOR THE ITEM OR ALL ROWS HAVE return_date POPULATED
SELECT count(*) INTO v_rentals
FROM rental
WHERE inventory_id = p_inventory_id;
IF v_rentals = 0 THEN
RETURN TRUE;
END IF;
SELECT COUNT(rental_id) INTO v_out
FROM inventory LEFT JOIN rental USING(inventory_id)
WHERE inventory.inventory_id = p_inventory_id
AND rental.return_date IS NULL;
IF v_out > 0 THEN
RETURN FALSE;
ELSE
RETURN TRUE;
END IF;
END $$;
ALTER FUNCTION public.inventory_in_stock(p_inventory_id integer) OWNER TO postgres;
--
-- Name: last_day(timestamp with time zone); Type: FUNCTION; Schema: public; Owner: postgres
--
CREATE FUNCTION public.last_day(timestamp with time zone) RETURNS date
LANGUAGE sql IMMUTABLE STRICT
AS $_$
SELECT CASE
WHEN EXTRACT(MONTH FROM $1) = 12 THEN
(((EXTRACT(YEAR FROM $1) + 1) operator(pg_catalog.||) '-01-01')::date - INTERVAL '1 day')::date
ELSE
((EXTRACT(YEAR FROM $1) operator(pg_catalog.||) '-' operator(pg_catalog.||) (EXTRACT(MONTH FROM $1) + 1) operator(pg_catalog.||) '-01')::date - INTERVAL '1 day')::date
END
$_$;
ALTER FUNCTION public.last_day(timestamp with time zone) OWNER TO postgres;
--
-- Name: last_updated(); Type: FUNCTION; Schema: public; Owner: postgres
--
CREATE FUNCTION public.last_updated() RETURNS trigger
LANGUAGE plpgsql
AS $$
BEGIN
NEW.last_update = CURRENT_TIMESTAMP;
RETURN NEW;
END $$;
ALTER FUNCTION public.last_updated() OWNER TO postgres;
--
-- Name: customer_customer_id_seq; Type: SEQUENCE; Schema: public; Owner: postgres
--
CREATE SEQUENCE public.customer_customer_id_seq
START WITH 1
INCREMENT BY 1
NO MINVALUE
NO MAXVALUE
CACHE 1;
ALTER TABLE public.customer_customer_id_seq OWNER TO postgres;
SET default_tablespace = '';
SET default_table_access_method = heap;
--
-- Name: customer; Type: TABLE; Schema: public; Owner: postgres
--
CREATE TABLE public.customer (
customer_id integer DEFAULT nextval('public.customer_customer_id_seq'::regclass) NOT NULL,
store_id integer NOT NULL,
first_name text NOT NULL,
last_name text NOT NULL,
email text,
address_id integer NOT NULL,
activebool boolean DEFAULT true NOT NULL,
create_date date DEFAULT CURRENT_DATE NOT NULL,
last_update timestamp with time zone DEFAULT now(),
active integer
);
ALTER TABLE public.customer OWNER TO postgres;
--
-- Name: rewards_report(integer, numeric); Type: FUNCTION; Schema: public; Owner: postgres
--
CREATE FUNCTION public.rewards_report(min_monthly_purchases integer, min_dollar_amount_purchased numeric) RETURNS SETOF public.customer
LANGUAGE plpgsql SECURITY DEFINER
AS $_$
DECLARE
last_month_start DATE;
last_month_end DATE;
rr RECORD;
tmpSQL TEXT;
BEGIN
/* Some sanity checks... */
IF min_monthly_purchases = 0 THEN
RAISE EXCEPTION 'Minimum monthly purchases parameter must be > 0';
END IF;
IF min_dollar_amount_purchased = 0.00 THEN
RAISE EXCEPTION 'Minimum monthly dollar amount purchased parameter must be > $0.00';
END IF;
last_month_start := CURRENT_DATE - '3 month'::interval;
last_month_start := to_date((extract(YEAR FROM last_month_start) || '-' || extract(MONTH FROM last_month_start) || '-01'),'YYYY-MM-DD');
last_month_end := LAST_DAY(last_month_start);
/*
Create a temporary storage area for Customer IDs.
*/
CREATE TEMPORARY TABLE tmpCustomer (customer_id INTEGER NOT NULL PRIMARY KEY);
/*
Find all customers meeting the monthly purchase requirements
*/
tmpSQL := 'INSERT INTO tmpCustomer (customer_id)
SELECT p.customer_id
FROM payment AS p
WHERE DATE(p.payment_date) BETWEEN '||quote_literal(last_month_start) ||' AND '|| quote_literal(last_month_end) || '
GROUP BY customer_id
HAVING SUM(p.amount) > '|| min_dollar_amount_purchased || '
AND COUNT(customer_id) > ' ||min_monthly_purchases ;
EXECUTE tmpSQL;
/*
Output ALL customer information of matching rewardees.
Customize output as needed.
*/
FOR rr IN EXECUTE 'SELECT c.* FROM tmpCustomer AS t INNER JOIN customer AS c ON t.customer_id = c.customer_id' LOOP
RETURN NEXT rr;
END LOOP;
/* Clean up */
tmpSQL := 'DROP TABLE tmpCustomer';
EXECUTE tmpSQL;
RETURN;
END
$_$;
ALTER FUNCTION public.rewards_report(min_monthly_purchases integer, min_dollar_amount_purchased numeric) OWNER TO postgres;
--
-- Name: group_concat(text); Type: AGGREGATE; Schema: public; Owner: postgres
--
CREATE AGGREGATE public.group_concat(text) (
SFUNC = public._group_concat,
STYPE = text
);
ALTER AGGREGATE public.group_concat(text) OWNER TO postgres;
--
-- Name: actor_actor_id_seq; Type: SEQUENCE; Schema: public; Owner: postgres
--
CREATE SEQUENCE public.actor_actor_id_seq
START WITH 1
INCREMENT BY 1
NO MINVALUE
NO MAXVALUE
CACHE 1;
ALTER TABLE public.actor_actor_id_seq OWNER TO postgres;
--
-- Name: actor; Type: TABLE; Schema: public; Owner: postgres
--
CREATE TABLE public.actor (
actor_id integer DEFAULT nextval('public.actor_actor_id_seq'::regclass) NOT NULL,
first_name text NOT NULL,
last_name text NOT NULL,
last_update timestamp with time zone DEFAULT now() NOT NULL
);
ALTER TABLE public.actor OWNER TO postgres;
--
-- Name: category_category_id_seq; Type: SEQUENCE; Schema: public; Owner: postgres
--
CREATE SEQUENCE public.category_category_id_seq
START WITH 1
INCREMENT BY 1
NO MINVALUE
NO MAXVALUE
CACHE 1;
ALTER TABLE public.category_category_id_seq OWNER TO postgres;
--
-- Name: category; Type: TABLE; Schema: public; Owner: postgres
--
CREATE TABLE public.category (
category_id integer DEFAULT nextval('public.category_category_id_seq'::regclass) NOT NULL,
name text NOT NULL,
last_update timestamp with time zone DEFAULT now() NOT NULL
);
ALTER TABLE public.category OWNER TO postgres;
--
-- Name: film_film_id_seq; Type: SEQUENCE; Schema: public; Owner: postgres
--
CREATE SEQUENCE public.film_film_id_seq
START WITH 1
INCREMENT BY 1
NO MINVALUE
NO MAXVALUE
CACHE 1;
ALTER TABLE public.film_film_id_seq OWNER TO postgres;
--
-- Name: film; Type: TABLE; Schema: public; Owner: postgres
--
CREATE TABLE public.film (
film_id integer DEFAULT nextval('public.film_film_id_seq'::regclass) NOT NULL,
title text NOT NULL,
description text,
release_year public.year,
language_id integer NOT NULL,
original_language_id integer,
rental_duration smallint DEFAULT 3 NOT NULL,
rental_rate numeric(4,2) DEFAULT 4.99 NOT NULL,
length smallint,
replacement_cost numeric(5,2) DEFAULT 19.99 NOT NULL,
rating public.mpaa_rating DEFAULT 'G'::public.mpaa_rating,
last_update timestamp with time zone DEFAULT now() NOT NULL,
special_features text[],
fulltext tsvector NOT NULL
);
ALTER TABLE public.film OWNER TO postgres;
--
-- Name: film_actor; Type: TABLE; Schema: public; Owner: postgres
--
CREATE TABLE public.film_actor (
actor_id integer NOT NULL,
film_id integer NOT NULL,
last_update timestamp with time zone DEFAULT now() NOT NULL
);
ALTER TABLE public.film_actor OWNER TO postgres;
--
-- Name: film_category; Type: TABLE; Schema: public; Owner: postgres
--
CREATE TABLE public.film_category (
film_id integer NOT NULL,
category_id integer NOT NULL,
last_update timestamp with time zone DEFAULT now() NOT NULL
);
ALTER TABLE public.film_category OWNER TO postgres;
--
-- Name: actor_info; Type: VIEW; Schema: public; Owner: postgres
--
CREATE VIEW public.actor_info AS
SELECT a.actor_id,
a.first_name,
a.last_name,
public.group_concat(DISTINCT ((c.name || ': '::text) || ( SELECT public.group_concat(f.title) AS group_concat
FROM ((public.film f
JOIN public.film_category fc_1 ON ((f.film_id = fc_1.film_id)))
JOIN public.film_actor fa_1 ON ((f.film_id = fa_1.film_id)))
WHERE ((fc_1.category_id = c.category_id) AND (fa_1.actor_id = a.actor_id))
GROUP BY fa_1.actor_id))) AS film_info
FROM (((public.actor a
LEFT JOIN public.film_actor fa ON ((a.actor_id = fa.actor_id)))
LEFT JOIN public.film_category fc ON ((fa.film_id = fc.film_id)))
LEFT JOIN public.category c ON ((fc.category_id = c.category_id)))
GROUP BY a.actor_id, a.first_name, a.last_name;
ALTER TABLE public.actor_info OWNER TO postgres;
--
-- Name: address_address_id_seq; Type: SEQUENCE; Schema: public; Owner: postgres
--
CREATE SEQUENCE public.address_address_id_seq
START WITH 1
INCREMENT BY 1
NO MINVALUE
NO MAXVALUE
CACHE 1;
ALTER TABLE public.address_address_id_seq OWNER TO postgres;
--
-- Name: address; Type: TABLE; Schema: public; Owner: postgres
--
CREATE TABLE public.address (
address_id integer DEFAULT nextval('public.address_address_id_seq'::regclass) NOT NULL,
address text NOT NULL,
address2 text,
district text NOT NULL,
city_id integer NOT NULL,
postal_code text,
phone text NOT NULL,
last_update timestamp with time zone DEFAULT now() NOT NULL
);
ALTER TABLE public.address OWNER TO postgres;
--
-- Name: city_city_id_seq; Type: SEQUENCE; Schema: public; Owner: postgres
--
CREATE SEQUENCE public.city_city_id_seq
START WITH 1
INCREMENT BY 1
NO MINVALUE
NO MAXVALUE
CACHE 1;
ALTER TABLE public.city_city_id_seq OWNER TO postgres;
--
-- Name: city; Type: TABLE; Schema: public; Owner: postgres
--
CREATE TABLE public.city (
city_id integer DEFAULT nextval('public.city_city_id_seq'::regclass) NOT NULL,
city text NOT NULL,
country_id integer NOT NULL,
last_update timestamp with time zone DEFAULT now() NOT NULL
);
ALTER TABLE public.city OWNER TO postgres;
--
-- Name: country_country_id_seq; Type: SEQUENCE; Schema: public; Owner: postgres
--
CREATE SEQUENCE public.country_country_id_seq
START WITH 1
INCREMENT BY 1
NO MINVALUE
NO MAXVALUE
CACHE 1;
ALTER TABLE public.country_country_id_seq OWNER TO postgres;
--
-- Name: country; Type: TABLE; Schema: public; Owner: postgres
--
CREATE TABLE public.country (
country_id integer DEFAULT nextval('public.country_country_id_seq'::regclass) NOT NULL,
country text NOT NULL,
last_update timestamp with time zone DEFAULT now() NOT NULL
);
ALTER TABLE public.country OWNER TO postgres;
--
-- Name: customer_list; Type: VIEW; Schema: public; Owner: postgres
--
CREATE VIEW public.customer_list AS
SELECT cu.customer_id AS id,
((cu.first_name || ' '::text) || cu.last_name) AS name,
a.address,
a.postal_code AS "zip code",
a.phone,
city.city,
country.country,
CASE
WHEN cu.activebool THEN 'active'::text
ELSE ''::text
END AS notes,
cu.store_id AS sid
FROM (((public.customer cu
JOIN public.address a ON ((cu.address_id = a.address_id)))
JOIN public.city ON ((a.city_id = city.city_id)))
JOIN public.country ON ((city.country_id = country.country_id)));
ALTER TABLE public.customer_list OWNER TO postgres;
--
-- Name: film_list; Type: VIEW; Schema: public; Owner: postgres
--
CREATE VIEW public.film_list AS
SELECT film.film_id AS fid,
film.title,
film.description,
category.name AS category,
film.rental_rate AS price,
film.length,
film.rating,
public.group_concat(((actor.first_name || ' '::text) || actor.last_name)) AS actors
FROM ((((public.category
LEFT JOIN public.film_category ON ((category.category_id = film_category.category_id)))
LEFT JOIN public.film ON ((film_category.film_id = film.film_id)))
JOIN public.film_actor ON ((film.film_id = film_actor.film_id)))
JOIN public.actor ON ((film_actor.actor_id = actor.actor_id)))
GROUP BY film.film_id, film.title, film.description, category.name, film.rental_rate, film.length, film.rating;
ALTER TABLE public.film_list OWNER TO postgres;
--
-- Name: inventory_inventory_id_seq; Type: SEQUENCE; Schema: public; Owner: postgres
--
CREATE SEQUENCE public.inventory_inventory_id_seq
START WITH 1
INCREMENT BY 1
NO MINVALUE
NO MAXVALUE
CACHE 1;
ALTER TABLE public.inventory_inventory_id_seq OWNER TO postgres;
--
-- Name: inventory; Type: TABLE; Schema: public; Owner: postgres
--
CREATE TABLE public.inventory (
inventory_id integer DEFAULT nextval('public.inventory_inventory_id_seq'::regclass) NOT NULL,
film_id integer NOT NULL,
store_id integer NOT NULL,
last_update timestamp with time zone DEFAULT now() NOT NULL
);
ALTER TABLE public.inventory OWNER TO postgres;
--
-- Name: language_language_id_seq; Type: SEQUENCE; Schema: public; Owner: postgres
--
CREATE SEQUENCE public.language_language_id_seq
START WITH 1
INCREMENT BY 1
NO MINVALUE
NO MAXVALUE
CACHE 1;
ALTER TABLE public.language_language_id_seq OWNER TO postgres;
--
-- Name: language; Type: TABLE; Schema: public; Owner: postgres
--
CREATE TABLE public.language (
language_id integer DEFAULT nextval('public.language_language_id_seq'::regclass) NOT NULL,
name character(20) NOT NULL,
last_update timestamp with time zone DEFAULT now() NOT NULL
);
ALTER TABLE public.language OWNER TO postgres;
--
-- Name: nicer_but_slower_film_list; Type: VIEW; Schema: public; Owner: postgres
--
CREATE VIEW public.nicer_but_slower_film_list AS
SELECT film.film_id AS fid,
film.title,
film.description,
category.name AS category,
film.rental_rate AS price,
film.length,
film.rating,
public.group_concat((((upper("substring"(actor.first_name, 1, 1)) || lower("substring"(actor.first_name, 2))) || upper("substring"(actor.last_name, 1, 1))) || lower("substring"(actor.last_name, 2)))) AS actors
FROM ((((public.category
LEFT JOIN public.film_category ON ((category.category_id = film_category.category_id)))
LEFT JOIN public.film ON ((film_category.film_id = film.film_id)))
JOIN public.film_actor ON ((film.film_id = film_actor.film_id)))
JOIN public.actor ON ((film_actor.actor_id = actor.actor_id)))
GROUP BY film.film_id, film.title, film.description, category.name, film.rental_rate, film.length, film.rating;
ALTER TABLE public.nicer_but_slower_film_list OWNER TO postgres;
--
-- Name: payment_payment_id_seq; Type: SEQUENCE; Schema: public; Owner: postgres
--
CREATE SEQUENCE public.payment_payment_id_seq
START WITH 1
INCREMENT BY 1
NO MINVALUE
NO MAXVALUE
CACHE 1;
ALTER TABLE public.payment_payment_id_seq OWNER TO postgres;
--
-- Name: payment; Type: TABLE; Schema: public; Owner: postgres
--
CREATE TABLE public.payment (
payment_id integer DEFAULT nextval('public.payment_payment_id_seq'::regclass) NOT NULL,
customer_id integer NOT NULL,
staff_id integer NOT NULL,
rental_id integer NOT NULL,
amount numeric(5,2) NOT NULL,
payment_date timestamp with time zone NOT NULL
)
PARTITION BY RANGE (payment_date);
ALTER TABLE public.payment OWNER TO postgres;
--
-- Name: payment_p2020_01; Type: TABLE; Schema: public; Owner: postgres
--
CREATE TABLE public.payment_p2020_01 (
payment_id integer DEFAULT nextval('public.payment_payment_id_seq'::regclass) NOT NULL,
customer_id integer NOT NULL,
staff_id integer NOT NULL,
rental_id integer NOT NULL,
amount numeric(5,2) NOT NULL,
payment_date timestamp with time zone NOT NULL
);
ALTER TABLE ONLY public.payment ATTACH PARTITION public.payment_p2020_01 FOR VALUES FROM ('2020-01-01 00:00:00+00') TO ('2020-02-01 00:00:00+00');
ALTER TABLE public.payment_p2020_01 OWNER TO postgres;
--
-- Name: payment_p2020_02; Type: TABLE; Schema: public; Owner: postgres
--
CREATE TABLE public.payment_p2020_02 (
payment_id integer DEFAULT nextval('public.payment_payment_id_seq'::regclass) NOT NULL,
customer_id integer NOT NULL,
staff_id integer NOT NULL,
rental_id integer NOT NULL,
amount numeric(5,2) NOT NULL,
payment_date timestamp with time zone NOT NULL
);
ALTER TABLE ONLY public.payment ATTACH PARTITION public.payment_p2020_02 FOR VALUES FROM ('2020-02-01 00:00:00+00') TO ('2020-03-01 00:00:00+00');
ALTER TABLE public.payment_p2020_02 OWNER TO postgres;
--
-- Name: payment_p2020_03; Type: TABLE; Schema: public; Owner: postgres
--
CREATE TABLE public.payment_p2020_03 (
payment_id integer DEFAULT nextval('public.payment_payment_id_seq'::regclass) NOT NULL,
customer_id integer NOT NULL,
staff_id integer NOT NULL,
rental_id integer NOT NULL,
amount numeric(5,2) NOT NULL,
payment_date timestamp with time zone NOT NULL
);
ALTER TABLE ONLY public.payment ATTACH PARTITION public.payment_p2020_03 FOR VALUES FROM ('2020-03-01 00:00:00+00') TO ('2020-04-01 01:00:00+01');
ALTER TABLE public.payment_p2020_03 OWNER TO postgres;
--
-- Name: payment_p2020_04; Type: TABLE; Schema: public; Owner: postgres
--
CREATE TABLE public.payment_p2020_04 (
payment_id integer DEFAULT nextval('public.payment_payment_id_seq'::regclass) NOT NULL,
customer_id integer NOT NULL,
staff_id integer NOT NULL,
rental_id integer NOT NULL,
amount numeric(5,2) NOT NULL,
payment_date timestamp with time zone NOT NULL
);
ALTER TABLE ONLY public.payment ATTACH PARTITION public.payment_p2020_04 FOR VALUES FROM ('2020-04-01 01:00:00+01') TO ('2020-05-01 01:00:00+01');
ALTER TABLE public.payment_p2020_04 OWNER TO postgres;
--
-- Name: payment_p2020_05; Type: TABLE; Schema: public; Owner: postgres
--
CREATE TABLE public.payment_p2020_05 (
payment_id integer DEFAULT nextval('public.payment_payment_id_seq'::regclass) NOT NULL,
customer_id integer NOT NULL,
staff_id integer NOT NULL,
rental_id integer NOT NULL,
amount numeric(5,2) NOT NULL,
payment_date timestamp with time zone NOT NULL
);
ALTER TABLE ONLY public.payment ATTACH PARTITION public.payment_p2020_05 FOR VALUES FROM ('2020-05-01 01:00:00+01') TO ('2020-06-01 01:00:00+01');
ALTER TABLE public.payment_p2020_05 OWNER TO postgres;
--
-- Name: payment_p2020_06; Type: TABLE; Schema: public; Owner: postgres
--
CREATE TABLE public.payment_p2020_06 (
payment_id integer DEFAULT nextval('public.payment_payment_id_seq'::regclass) NOT NULL,
customer_id integer NOT NULL,
staff_id integer NOT NULL,
rental_id integer NOT NULL,
amount numeric(5,2) NOT NULL,
payment_date timestamp with time zone NOT NULL
);
ALTER TABLE ONLY public.payment ATTACH PARTITION public.payment_p2020_06 FOR VALUES FROM ('2020-06-01 01:00:00+01') TO ('2020-07-01 01:00:00+01');
ALTER TABLE public.payment_p2020_06 OWNER TO postgres;
--
-- Name: rental_rental_id_seq; Type: SEQUENCE; Schema: public; Owner: postgres
--
CREATE SEQUENCE public.rental_rental_id_seq
START WITH 1
INCREMENT BY 1
NO MINVALUE
NO MAXVALUE
CACHE 1;
ALTER TABLE public.rental_rental_id_seq OWNER TO postgres;
--
-- Name: rental; Type: TABLE; Schema: public; Owner: postgres
--
CREATE TABLE public.rental (
rental_id integer DEFAULT nextval('public.rental_rental_id_seq'::regclass) NOT NULL,
rental_date timestamp with time zone NOT NULL,
inventory_id integer NOT NULL,
customer_id integer NOT NULL,
return_date timestamp with time zone,
staff_id integer NOT NULL,
last_update timestamp with time zone DEFAULT now() NOT NULL
);
ALTER TABLE public.rental OWNER TO postgres;
--
-- Name: sales_by_film_category; Type: VIEW; Schema: public; Owner: postgres
--
CREATE VIEW public.sales_by_film_category AS
SELECT c.name AS category,
sum(p.amount) AS total_sales
FROM (((((public.payment p
JOIN public.rental r ON ((p.rental_id = r.rental_id)))
JOIN public.inventory i ON ((r.inventory_id = i.inventory_id)))
JOIN public.film f ON ((i.film_id = f.film_id)))
JOIN public.film_category fc ON ((f.film_id = fc.film_id)))
JOIN public.category c ON ((fc.category_id = c.category_id)))
GROUP BY c.name
ORDER BY (sum(p.amount)) DESC;
ALTER TABLE public.sales_by_film_category OWNER TO postgres;
--
-- Name: staff_staff_id_seq; Type: SEQUENCE; Schema: public; Owner: postgres
--
CREATE SEQUENCE public.staff_staff_id_seq
START WITH 1
INCREMENT BY 1
NO MINVALUE
NO MAXVALUE
CACHE 1;
ALTER TABLE public.staff_staff_id_seq OWNER TO postgres;
--
-- Name: staff; Type: TABLE; Schema: public; Owner: postgres
--
CREATE TABLE public.staff (
staff_id integer DEFAULT nextval('public.staff_staff_id_seq'::regclass) NOT NULL,
first_name text NOT NULL,
last_name text NOT NULL,
address_id integer NOT NULL,
email text,
store_id integer NOT NULL,
active boolean DEFAULT true NOT NULL,
username text NOT NULL,
password text,
last_update timestamp with time zone DEFAULT now() NOT NULL,
picture bytea
);
ALTER TABLE public.staff OWNER TO postgres;
--
-- Name: store_store_id_seq; Type: SEQUENCE; Schema: public; Owner: postgres
--
CREATE SEQUENCE public.store_store_id_seq
START WITH 1
INCREMENT BY 1
NO MINVALUE
NO MAXVALUE
CACHE 1;
ALTER TABLE public.store_store_id_seq OWNER TO postgres;
--
-- Name: store; Type: TABLE; Schema: public; Owner: postgres
--
CREATE TABLE public.store (
store_id integer DEFAULT nextval('public.store_store_id_seq'::regclass) NOT NULL,
manager_staff_id integer NOT NULL,
address_id integer NOT NULL,
last_update timestamp with time zone DEFAULT now() NOT NULL
);
ALTER TABLE public.store OWNER TO postgres;
--
-- Name: sales_by_store; Type: VIEW; Schema: public; Owner: postgres
--
CREATE VIEW public.sales_by_store AS
SELECT ((c.city || ','::text) || cy.country) AS store,
((m.first_name || ' '::text) || m.last_name) AS manager,
sum(p.amount) AS total_sales
FROM (((((((public.payment p
JOIN public.rental r ON ((p.rental_id = r.rental_id)))
JOIN public.inventory i ON ((r.inventory_id = i.inventory_id)))
JOIN public.store s ON ((i.store_id = s.store_id)))
JOIN public.address a ON ((s.address_id = a.address_id)))
JOIN public.city c ON ((a.city_id = c.city_id)))
JOIN public.country cy ON ((c.country_id = cy.country_id)))
JOIN public.staff m ON ((s.manager_staff_id = m.staff_id)))
GROUP BY cy.country, c.city, s.store_id, m.first_name, m.last_name
ORDER BY cy.country, c.city;
ALTER TABLE public.sales_by_store OWNER TO postgres;
--
-- Name: staff_list; Type: VIEW; Schema: public; Owner: postgres
--
CREATE VIEW public.staff_list AS
SELECT s.staff_id AS id,
((s.first_name || ' '::text) || s.last_name) AS name,
a.address,
a.postal_code AS "zip code",
a.phone,
city.city,
country.country,
s.store_id AS sid
FROM (((public.staff s
JOIN public.address a ON ((s.address_id = a.address_id)))
JOIN public.city ON ((a.city_id = city.city_id)))
JOIN public.country ON ((city.country_id = country.country_id)));
ALTER TABLE public.staff_list OWNER TO postgres;
--
-- Name: actor actor_pkey; Type: CONSTRAINT; Schema: public; Owner: postgres
--
ALTER TABLE ONLY public.actor
ADD CONSTRAINT actor_pkey PRIMARY KEY (actor_id);
--
-- Name: address address_pkey; Type: CONSTRAINT; Schema: public; Owner: postgres
--