├── Chapter12 ├── echo_hidden.sql ├── set_statement_timeout.sql ├── get_information_schema_view.sql ├── terminate_all.sql ├── get_stat_table.sql ├── get_oid.sql ├── get_empty_relation_and_column.sql ├── test_setting_configuration.sql ├── get_object_size.sql ├── remove_duplicate_tuple.sql ├── get_table_without_primary_key.sql ├── get_overlapping_index.sql ├── monitor_view.sql ├── get_unused_index.sql └── get_view_dependency.sql ├── Chapter01 ├── rename_operator.sql ├── not_operator.sql └── and_or_operator.sql ├── Chapter03 ├── schema_search_path.sql ├── settings_count.sql ├── daylight.sql ├── check_char_trailing_space.sql ├── verbosity.sql ├── qualified_name.sql ├── read_only_transaction.sql ├── date_interval.sql ├── number_cast.sql ├── check_trailing_space.sql ├── emulate_varchar.sql ├── serial.sql ├── data_connection_limit.sql ├── meta_command.sql ├── text_data_type_size.sql ├── date_time.sql ├── identity.sql └── car_portal │ └── schema.sql ├── Chapter16 └── Scalability │ ├── logical_replication_multi_master │ ├── data.sql │ ├── publisher.sql │ ├── subscriber.sql │ ├── docker-compose.yml │ ├── schema.sql │ ├── Dockerfile-subscriber │ └── Dockerfile-publisher │ ├── logical_replication │ ├── publisher.sql │ ├── subscriber.sql │ ├── docker-compose.yml │ ├── Dockerfile-subscriber │ ├── Dockerfile-publisher │ └── schema.sql │ └── streaming_replication │ ├── master.sql │ ├── recovery.conf │ ├── docker-compose.yml │ ├── Dockerfile-standby │ ├── Dockerfile-master │ └── schema.sql ├── Chapter04 ├── fact_c │ ├── install_server_dev.sh │ ├── build.sh │ ├── makefile │ └── fact.c ├── sql_examples │ ├── rule.sql │ ├── function.sql │ ├── view.sql │ ├── user_data_type.sql │ ├── index.sql │ └── trigger.sql └── car_portal │ └── schema.sql ├── Chapter02 ├── proc_number.sh ├── postgres_install_apt_ubuntu.txt ├── postgres_install_source.txt ├── phone_type.sql └── file_fdw_log.sql ├── Chapter14 └── Testing │ ├── test.sql │ ├── pgtap.sql │ ├── schema.sql │ ├── examples.sql │ ├── old_db.sql │ └── new_db.sql ├── Chapter11 ├── gpg_command.txt ├── car_portal │ └── schema.sql └── security.sql ├── Chapter15 └── Using PostgreSQL in Python applications │ ├── print_makes.py │ ├── psycopg2_insert_data.py │ ├── print_makes_async.py │ ├── psycopg2_copy_data.py │ ├── asyncpg_raise_notice.py │ ├── psycopg2_pool.py │ ├── pg8000_query_data.py │ ├── psycopg2_query_data.py │ ├── sqlalchemy_sql_expression_language.py │ ├── sqlalchemy_orm.py │ └── schema.sql ├── LICENSE ├── Chapter09 ├── hstore.sql ├── text_search.sql ├── json.sql └── array.sql ├── Chapter06 └── Advanced Query Writing │ ├── schema.sql │ └── examples.sql ├── Chapter08 └── OLAP and data warehousing │ ├── schema.sql │ └── examples.sql ├── Chapter05 └── SQL Language │ ├── schema.sql │ └── examples.sql ├── Chapter07 ├── car_portal │ └── schema.sql └── plpgsql.sql ├── README.md └── Chapter10 └── transaction.sql /Chapter12/echo_hidden.sql: -------------------------------------------------------------------------------- 1 | \set ECHO_HIDDEN 2 | \d -------------------------------------------------------------------------------- /Chapter01/rename_operator.sql: -------------------------------------------------------------------------------- 1 | SELECT 3.14::real AS PI; 2 | -------------------------------------------------------------------------------- /Chapter03/schema_search_path.sql: -------------------------------------------------------------------------------- 1 | SHOW search_path; 2 | -------------------------------------------------------------------------------- /Chapter16/Scalability/logical_replication_multi_master/data.sql: -------------------------------------------------------------------------------- 1 | -------------------------------------------------------------------------------- /Chapter03/settings_count.sql: -------------------------------------------------------------------------------- 1 | SELECT count(*) FROM pg_settings; 2 | -------------------------------------------------------------------------------- /Chapter12/set_statement_timeout.sql: -------------------------------------------------------------------------------- 1 | SET statement_timeout to 1000; 2 | SELECT pg_sleep(1001); -------------------------------------------------------------------------------- /Chapter03/daylight.sql: -------------------------------------------------------------------------------- 1 | SET timezone TO 'Europe/Berlin'; 2 | SELECT '2017-03-26 2:00:00'::timestamptz; 3 | -------------------------------------------------------------------------------- /Chapter04/fact_c/install_server_dev.sh: -------------------------------------------------------------------------------- 1 | #!/bin/bash 2 | sudo apt-get install postgresql-server-dev-11 3 | -------------------------------------------------------------------------------- /Chapter03/check_char_trailing_space.sql: -------------------------------------------------------------------------------- 1 | SELECT 'a'::CHAR(2) = 'a '::CHAR(2) AS "Trailing space is ignored" ,length('a '::CHAR(10)); 2 | -------------------------------------------------------------------------------- /Chapter12/get_information_schema_view.sql: -------------------------------------------------------------------------------- 1 | SELECT * FROM information_schema.views where table_schema IN ('pg_catlog', 'information_schema'); -------------------------------------------------------------------------------- /Chapter16/Scalability/logical_replication/publisher.sql: -------------------------------------------------------------------------------- 1 | ALTER USER car_portal_app REPLICATION; 2 | CREATE PUBLICATION car_portal FOR ALL TABLES; -------------------------------------------------------------------------------- /Chapter12/terminate_all.sql: -------------------------------------------------------------------------------- 1 | SELECT pg_terminate_backend(pid) FROM pg_stat_activity WHERE datname = current_database() AND pid <> pg_backend_pid(); -------------------------------------------------------------------------------- /Chapter16/Scalability/streaming_replication/master.sql: -------------------------------------------------------------------------------- 1 | CREATE USER streamer REPLICATION; 2 | SELECT * FROM pg_create_physical_replication_slot('slot1'); -------------------------------------------------------------------------------- /Chapter02/proc_number.sh: -------------------------------------------------------------------------------- 1 | #!/bin/bash 2 | proc_number=`PGOPTIONS='--statement_timeout=0' psql -AqXt -c"SELECT count(*) FROM pg_stat_activity"` 3 | echo $proc_number -------------------------------------------------------------------------------- /Chapter03/verbosity.sql: -------------------------------------------------------------------------------- 1 | \set VERBOSITY 'verbose' 2 | CREATE TABLE user AS SELECT 1; 3 | BEGIN; 4 | \echo this will work 5 | CREATE TABLE "user" AS SELECT 1; 6 | ROLLBACK; 7 | -------------------------------------------------------------------------------- /Chapter16/Scalability/logical_replication_multi_master/publisher.sql: -------------------------------------------------------------------------------- 1 | ALTER USER car_portal_app REPLICATION; 2 | CREATE PUBLICATION car_model FOR TABLE car_portal_app.car_model; -------------------------------------------------------------------------------- /Chapter12/get_stat_table.sql: -------------------------------------------------------------------------------- 1 | SELECT relname, case relkind when 'r' then 'table' WHEN 'v' THEN 'VIEW' END as type FROM pg_class WHERE relname like 'pg_sta%' AND relkind IN ('r','v') LIMIT 5 ; -------------------------------------------------------------------------------- /Chapter14/Testing/test.sql: -------------------------------------------------------------------------------- 1 | SELECT count(*) FROM car_portal_app.car; 2 | SELECT * FROM car_portal_app.car INNER JOIN car_portal_app.car_model 3 | USING (car_model_id) ORDER BY car_id LIMIT 20; -------------------------------------------------------------------------------- /Chapter03/qualified_name.sql: -------------------------------------------------------------------------------- 1 | -- The . is used to specify the schema 2 | SELECT * FROM pg_catalog.pg_database; 3 | --Alternatively you can also use the following command: 4 | TABLE pg_catalog.pg_database; 5 | -------------------------------------------------------------------------------- /Chapter16/Scalability/logical_replication/subscriber.sql: -------------------------------------------------------------------------------- 1 | SET ROLE postgres; 2 | CREATE SUBSCRIPTION car_portal CONNECTION 'dbname=car_portal host=publisher user=car_portal_app' PUBLICATION car_portal; 3 | -------------------------------------------------------------------------------- /Chapter11/gpg_command.txt: -------------------------------------------------------------------------------- 1 | gpg --gen-key 2 | gpg --list-secret-key 3 | gpg -a --export public_key >/var/lib/postgresql/11/main/public.key 4 | gpg -a --export-secret-key private_key >/var/lib/postgresql/11/main/secret.key -------------------------------------------------------------------------------- /Chapter03/read_only_transaction.sql: -------------------------------------------------------------------------------- 1 | -- We are not allowed to insert, update, or delete data in read only mode. Also we can not create table 2 | SET default_transaction_read_only to on; 3 | CREATE TABLE test_readonly AS SELECT 1; 4 | -------------------------------------------------------------------------------- /Chapter12/get_oid.sql: -------------------------------------------------------------------------------- 1 | SELECT 'pg_catalog.pg_class'::regclass::oid; 2 | SELECT 1259::regclass::text; 3 | SELECT c.oid FROM pg_class c join pg_namespace n ON (c.relnamespace = n.oid) WHERE relname ='pg_class' AND nspname ='pg_catalog'; -------------------------------------------------------------------------------- /Chapter12/get_empty_relation_and_column.sql: -------------------------------------------------------------------------------- 1 | SELECT relname FROM pg_stat_user_tables WHERE n_live_tup= 0; 2 | SELECT schemaname, tablename, attname FROM pg_stats WHERE null_frac= 1 and schemaname NOT IN ('pg_catalog', 'information_schema'); 3 | -------------------------------------------------------------------------------- /Chapter01/not_operator.sql: -------------------------------------------------------------------------------- 1 | \pset null null 2 | WITH data (v) as (VALUES (true), (false),(null)) 3 | SELECT 4 | v::TEXT as a, 5 | (NOT v)::TEXT as "NOT a" 6 | FROM 7 | data 8 | ORDER BY a DESC nulls last; 9 | -------------------------------------------------------------------------------- /Chapter03/date_interval.sql: -------------------------------------------------------------------------------- 1 | SELECT 2 | '2014-10-11'::date -'2014-10-10'::date = 1 AS "date Subtraction", 3 | '2014-09-01 23:30:00'::timestamptz -'2014-09-01 22:00:00'::timestamptz= Interval '1 hour, 30 minutes' AS "Time stamp subtraction"; 4 | 5 | -------------------------------------------------------------------------------- /Chapter16/Scalability/streaming_replication/recovery.conf: -------------------------------------------------------------------------------- 1 | standby_mode = 'on' 2 | primary_conninfo = 'host=master port=5432 user=streamer application_name=standby1' 3 | primary_slot_name = 'slot1' 4 | trigger_file = '/var/lib/postgresql/10/main/start' -------------------------------------------------------------------------------- /Chapter04/fact_c/build.sh: -------------------------------------------------------------------------------- 1 | #!/bin/bash 2 | make -f makefile 3 | sudo cp fact.so $(pg_config --pkglibdir)/ 4 | psql -d template1 -c "CREATE FUNCTION fact(INTEGER) RETURNS INTEGER AS 'fact', 'fact' LANGUAGE C STRICT;" 5 | psql -d template1 -c "SELECT fact(5);" -------------------------------------------------------------------------------- /Chapter03/number_cast.sql: -------------------------------------------------------------------------------- 1 | SELECT 2 | CAST(5.9 AS INT) AS "CAST (5.9 AS INT)", 3 | CAST(5.1 AS INT) AS "CAST(5.1 AS INT)", 4 | CAST(-23.5 AS INT) AS "CAST(-23.5 AS INT)" , 5 | 5.5::INT AS "5.5::INT"; 6 | 7 | SELECT 2/3 AS "2/3", 1/3 AS "1/3", 3/2 AS "3/2"; 8 | -------------------------------------------------------------------------------- /Chapter03/check_trailing_space.sql: -------------------------------------------------------------------------------- 1 | SELECT 2 | 'a '::VARCHAR(2) = 'a '::TEXT AS "Text and varchar", 3 | 'a '::CHAR(2) = 'a '::TEXT AS "Char and text", 4 | 'a '::CHAR(2) = 'a '::VARCHAR(2) AS "Char and varchar"; 5 | 6 | SELECT length ('a '::CHAR(2)), length ('a '::VARCHAR(2)); 7 | -------------------------------------------------------------------------------- /Chapter03/emulate_varchar.sql: -------------------------------------------------------------------------------- 1 | BEGIN; 2 | 3 | --CREATE TABLE emulate_varchar( 4 | -- test VARCHAR(4) 5 | --); 6 | --semantically equivalent to 7 | CREATE TABLE emulate_varchar ( 8 | test TEXT, 9 | CONSTRAINT test_length CHECK (length(test) <= 4) 10 | ); 11 | ROLLBACK; 12 | -------------------------------------------------------------------------------- /Chapter03/serial.sql: -------------------------------------------------------------------------------- 1 | BEGIN; 2 | CREATE TABLE customer ( 3 | customer_id SERIAL 4 | ); 5 | \echo Describe the table, note the Type and the Deafult 6 | \d+ customer 7 | \echo Describe the sequence created by using serial 8 | \ds customer_customer_id_seq 9 | ROLLBACK; 10 | 11 | -------------------------------------------------------------------------------- /Chapter12/test_setting_configuration.sql: -------------------------------------------------------------------------------- 1 | SELECT current_setting('work_mem'); 2 | show work_mem; 3 | SELECT set_config('work_mem', '8 MB', false); 4 | SELECT set_config('shared_buffers', '1 GB', false); 5 | SELECT name, current_setting(name), source FROM pg_settings WHERE source IN ('configuration file'); -------------------------------------------------------------------------------- /Chapter03/data_connection_limit.sql: -------------------------------------------------------------------------------- 1 | -- We use rollback because we do not want to persist the change 2 | BEGIN; 3 | SELECT datconnlimit FROM pg_database WHERE datname='postgres'; 4 | ALTER DATABASE postgres CONNECTION LIMIT 1; 5 | SELECT datconnlimit FROM pg_database WHERE datname='postgres'; 6 | ROLLBACK; 7 | -------------------------------------------------------------------------------- /Chapter03/meta_command.sql: -------------------------------------------------------------------------------- 1 | -- This should be executed with psql 2 | \echo The "\echo" command is used to print messages 3 | \echo To list the databses, "\l" can beused 4 | \l 5 | \echo "\c" meta command allows us to connnect to database 6 | \echo We can not connect by defaul to template0 database 7 | \c template0 8 | 9 | -------------------------------------------------------------------------------- /Chapter04/fact_c/makefile: -------------------------------------------------------------------------------- 1 | MODULES = fact 2 | 3 | PG_CONFIG = pg_config 4 | PGXS = $(shell $(PG_CONFIG) --pgxs) 5 | INCLUDEDIR = $(shell $(PG_CONFIG) --includedir-server) 6 | include $(PGXS) 7 | 8 | fact.so: fact.o 9 | cc -shared -o fact.so fact.o 10 | 11 | fact.o: fact.c 12 | cc -o fact.o -c fact.c $(CFLAGS) -I$(INCLUDEDIR) -------------------------------------------------------------------------------- /Chapter12/get_object_size.sql: -------------------------------------------------------------------------------- 1 | SELECT pg_database.datname, pg_size_pretty(pg_database_size(pg_database.datname)) AS size FROM pg_database; 2 | SELECT tablename, pg_size_pretty(pg_total_relation_size(schemaname||'.'||tablename)) FROM pg_tables LIMIT 2; 3 | SELECT indexrelid::regclass, pg_size_pretty(pg_relation_size(indexrelid::regclass)) FROM pg_index LIMIT 2; -------------------------------------------------------------------------------- /Chapter12/remove_duplicate_tuple.sql: -------------------------------------------------------------------------------- 1 | CREATE TABLE duplicate AS SELECT (random () * 9 + 1)::INT as f1 , (random () * 9 + 1)::INT as f2 FROM generate_series (1,40); 2 | SELECT count(*), f1, f2 FROM duplicate GROUP BY f1, f2; 3 | SELECT ctid, f1, f2 FROM duplicate; 4 | DELETE FROM duplicate a USING duplicate b WHERE a.f1= b.f1 and a.f2= b.f2 and a.ctid > b.ctid; 5 | -------------------------------------------------------------------------------- /Chapter15/Using PostgreSQL in Python applications/print_makes.py: -------------------------------------------------------------------------------- 1 | #!/usr/bin/python3 2 | 3 | from psycopg2 import connect 4 | 5 | conn = connect(host="localhost", user="car_portal_app", dbname="car_portal") 6 | 7 | with conn.cursor() as cur: 8 | cur.execute("SELECT DISTINCT make FROM car_portal_app.car_model") 9 | for row in cur: 10 | print(row[0]) 11 | 12 | conn.close() 13 | -------------------------------------------------------------------------------- /Chapter16/Scalability/logical_replication_multi_master/subscriber.sql: -------------------------------------------------------------------------------- 1 | SET ROLE postgres; 2 | ALTER TABLE car_portal_app.car_model DROP CONSTRAINT car_model_pkey; 3 | CREATE SUBSCRIPTION car_model_a CONNECTION 'dbname=car_portal host=publisher-a user=car_portal_app' PUBLICATION car_model; 4 | CREATE SUBSCRIPTION car_model_b CONNECTION 'dbname=car_portal host=publisher-b user=car_portal_app' PUBLICATION car_model; 5 | -------------------------------------------------------------------------------- /Chapter04/fact_c/fact.c: -------------------------------------------------------------------------------- 1 | #include "postgres.h" 2 | #include "fmgr.h" 3 | #ifdef PG_MODULE_MAGIC 4 | PG_MODULE_MAGIC; 5 | #endif 6 | Datum fact(PG_FUNCTION_ARGS); 7 | PG_FUNCTION_INFO_V1(fact); 8 | Datum 9 | fact(PG_FUNCTION_ARGS) { 10 | int32 fact = PG_GETARG_INT32(0); 11 | int32 count = 1, result = 1; 12 | for (count = 1; count <= fact; count++) 13 | result = result * count; 14 | PG_RETURN_INT32(result); 15 | } -------------------------------------------------------------------------------- /Chapter02/postgres_install_apt_ubuntu.txt: -------------------------------------------------------------------------------- 1 | sudo sh -c 'echo "deb http://apt.PostgreSQL.org/pub/repos/apt/ $(lsb_release -cs)-pgdg main" > /etc/apt/sources.list.d/pgdg.list' 2 | wget --quiet -O - https://www.PostgreSQL.org/media/keys/ACCC4CF8.asc | sudo apt-key add - 3 | sudo apt-get update 4 | sudo apt-get upgrade 5 | sudo apt-get install postgresql-client-11 6 | sudo apt-get install pgadmin4 7 | sudo apt-get install postgresql-11 8 | -------------------------------------------------------------------------------- /Chapter01/and_or_operator.sql: -------------------------------------------------------------------------------- 1 | \pset null null 2 | WITH data (v) as (VALUES (true), (false),(null)) 3 | SELECT DISTINCT 4 | first.v::TEXT as a, 5 | second.v::TEXT as b, 6 | (first.v AND second.v)::TEXT AS "a and b", 7 | (first.v OR second.v)::TEXT as "a or b" 8 | FROM 9 | data as first cross join 10 | data as second 11 | ORDER BY a DESC nulls last, b DESC nulls last; 12 | -------------------------------------------------------------------------------- /Chapter12/get_table_without_primary_key.sql: -------------------------------------------------------------------------------- 1 | SELECT table_catalog, table_schema, table_name 2 | FROM 3 | information_schema.tables 4 | WHERE 5 | table_schema NOT IN ('information_schema','pg_catalog') 6 | EXCEPT 7 | SELECT 8 | table_catalog, table_schema, table_name 9 | FROM 10 | information_schema.table_constraints 11 | WHERE 12 | constraint_type IN ('PRIMARY KEY', 'UNIQUE') AND table_schema NOT IN ('information_schema', 'pg_catalog'); -------------------------------------------------------------------------------- /Chapter16/Scalability/logical_replication/docker-compose.yml: -------------------------------------------------------------------------------- 1 | version: '2.1' 2 | 3 | services: 4 | 5 | publisher: 6 | hostname: publisher 7 | build: 8 | context: . 9 | dockerfile: Dockerfile-publisher 10 | ports: 11 | - "15432:5432" 12 | 13 | subscriber: 14 | hostname: subscriber 15 | build: 16 | context: . 17 | dockerfile: Dockerfile-subscriber 18 | ports: 19 | - "25432:5432" 20 | -------------------------------------------------------------------------------- /Chapter16/Scalability/streaming_replication/docker-compose.yml: -------------------------------------------------------------------------------- 1 | version: '2.1' 2 | 3 | services: 4 | 5 | master: 6 | hostname: master 7 | build: 8 | context: . 9 | dockerfile: Dockerfile-master 10 | ports: 11 | - "15432:5432" 12 | 13 | standby: 14 | hostname: standby 15 | build: 16 | context: . 17 | dockerfile: Dockerfile-standby 18 | ports: 19 | - "25432:5432" 20 | links: 21 | - master:master 22 | -------------------------------------------------------------------------------- /Chapter12/get_overlapping_index.sql: -------------------------------------------------------------------------------- 1 | SELECT 2 | conrelid::regclass AS relation_name, 3 | conname AS constraint_name, 4 | reltuples::bigint AS number_of_rows, 5 | indkey AS index_attributes, 6 | conkey AS constraint_attributes, 7 | CASE WHEN conkey && string_to_array(indkey::text, ' ')::SMALLINT[] THEN FALSE ELSE TRUE END as might_require_index 8 | FROM 9 | pg_constraint JOIN pg_class ON (conrelid = pg_class.oid) JOIN 10 | pg_index ON indrelid = conrelid 11 | WHERE 12 | contype = 'f'; -------------------------------------------------------------------------------- /Chapter03/text_data_type_size.sql: -------------------------------------------------------------------------------- 1 | BEGIN; 2 | 3 | CREATE TABLE char_size_test ( 4 | size CHAR(10) 5 | ); 6 | CREATE TABLE varchar_size_test( 7 | size varchar(10) 8 | ); 9 | WITH test_data AS ( 10 | SELECT substring(md5(random()::text), 1, 5) FROM generate_series (1, 1000000) 11 | ),char_data_insert AS ( 12 | INSERT INTO char_size_test SELECT * FROM test_data 13 | )INSERT INTO varchar_size_test SELECT * FROM test_data; 14 | 15 | \dt+ varchar_size_test 16 | \dt+ char_size_test 17 | 18 | ROLLBACK; 19 | -------------------------------------------------------------------------------- /Chapter15/Using PostgreSQL in Python applications/psycopg2_insert_data.py: -------------------------------------------------------------------------------- 1 | #!/usr/bin/python3 2 | 3 | from psycopg2 import connect 4 | 5 | conn = connect(host="localhost", user="car_portal_app", dbname="car_portal") 6 | 7 | with conn.cursor() as cur: 8 | new_make = "Ford" 9 | new_model = "Mustang" 10 | query = "INSERT INTO car_portal_app.car_model (make, model) " \ 11 | "VALUES (%s, %s)" 12 | cur.execute(query, [new_make, new_model]) 13 | print("1 record inserted") 14 | 15 | conn.commit() 16 | conn.close() 17 | -------------------------------------------------------------------------------- /Chapter16/Scalability/logical_replication_multi_master/docker-compose.yml: -------------------------------------------------------------------------------- 1 | version: '2.1' 2 | 3 | services: 4 | 5 | publisher-a: 6 | hostname: publisher-a 7 | build: 8 | context: . 9 | dockerfile: Dockerfile-publisher 10 | 11 | publisher-b: 12 | hostname: publisher-b 13 | build: 14 | context: . 15 | dockerfile: Dockerfile-publisher 16 | 17 | subscriber: 18 | hostname: subscriber 19 | build: 20 | context: . 21 | dockerfile: Dockerfile-subscriber 22 | ports: 23 | - "25432:5432" 24 | -------------------------------------------------------------------------------- /Chapter02/postgres_install_source.txt: -------------------------------------------------------------------------------- 1 | sudo apt-get install build-essential 2 | sudo apt-get install zlib1g-dev libreadline6-dev 3 | wget https://ftp.postgresql.org/pub/source/v11.1/postgresql-11.1.tar.bz2 4 | tar -xvf postgresql-11.1.tar.bz2 5 | cd postgresql-11.1 6 | ./configure 7 | make 8 | sudo su 9 | make install 10 | adduser postgres 11 | mkdir /usr/local/pgsql/data 12 | chown postgres /usr/local/pgsql/data 13 | su - postgres 14 | /usr/local/pgsql/bin/initdb -D /usr/local/pgsql/data 15 | /usr/local/pgsql/bin/postgres -D /usr/local/pgsql/data >logfile 2>&1 & 16 | /usr/local/pgsql/bin/psql postgres -------------------------------------------------------------------------------- /Chapter03/date_time.sql: -------------------------------------------------------------------------------- 1 | \echo get the time in Jerusalem 2 | SET timezone TO 'Asia/jerusalem'; 3 | SELECT now(); 4 | 5 | \echo figure out conversion between timestamp with and without time zone 6 | SHOW timezone; 7 | \x 8 | SELECT 9 | now() AS "Return current timestap in Jerusalem", 10 | now()::timestamp AS "Return current timestap in Jerusalem with out time zone information", 11 | now() AT TIME ZONE 'CST' AS "Return current time in Central Standard Time without time zone information", 12 | '2018-08-19:00:00:00'::timestamp AT TIME ZONE 'CST' AS "Convert the time in CST to Jerusalem time zone"; 13 | -------------------------------------------------------------------------------- /Chapter12/monitor_view.sql: -------------------------------------------------------------------------------- 1 | CREATE OR REPLACE FUNCTION monitor_view_usage (view_name TEXT) RETURNS BOOLEAN AS $$ 2 | BEGIN 3 | RAISE LOG 'The view % is used on % by % ', view_name, current_time, session_user; 4 | RETURN TRUE; 5 | END; 6 | $$LANGUAGE plpgsql cost .001; 7 | 8 | CREATE OR REPLACE VIEW dummy_view AS 9 | SELECT dummy_text FROM (VALUES('dummy')) as dummy(dummy_text); 10 | 11 | -- Recreat the view and inject the monitor_view_usage 12 | CREATE OR REPLACE VIEW dummy_view AS 13 | SELECT dummy_text FROM (VALUES('dummy')) as dummy(dummy_text) cross join monitor_view_usage('dummy_view'); 14 | 15 | SELECT * FROM dummy_view; 16 | -------------------------------------------------------------------------------- /Chapter14/Testing/pgtap.sql: -------------------------------------------------------------------------------- 1 | -- Isolate test scenario in its own transaction 2 | BEGIN; 3 | -- report 2 tests will be run 4 | SELECT plan(5); 5 | -- Validate the schema 6 | SELECT has_table('counter_table'); 7 | SELECT has_column('counter_table', 'counter'); 8 | SELECT has_function('increment_counter'); 9 | -- Test 1. Call the increment function 10 | SELECT lives_ok('SELECT increment_counter()','Call increment function'); 11 | -- Test 2. The results are correct 12 | SELECT is( (SELECT ARRAY [COUNT(*), MAX(counter)]::text FROM counter_table), ARRAY [1, 0]::text,'The results are correct'); 13 | -- Report finish 14 | SELECT finish(); 15 | -- Rollback changes made by the test 16 | ROLLBACK; -------------------------------------------------------------------------------- /Chapter15/Using PostgreSQL in Python applications/print_makes_async.py: -------------------------------------------------------------------------------- 1 | #!/usr/bin/python3 2 | 3 | from psycopg2 import connect 4 | from psycopg2.extras import wait_select 5 | from time import sleep 6 | 7 | aconn = connect(host="localhost", user="car_portal_app", dbname="car_portal", 8 | async=1) 9 | wait_select(aconn) 10 | 11 | acur = aconn.cursor() 12 | acur.execute("SELECT DISTINCT make FROM car_portal_app.car_model, " 13 | "pg_sleep(10)") 14 | 15 | for i in range(8): 16 | print("waiting... " + str(i)) 17 | sleep(1) 18 | 19 | wait_select(aconn) 20 | 21 | for row in acur: 22 | print(row[0]) 23 | 24 | acur.close() 25 | aconn.close() 26 | -------------------------------------------------------------------------------- /Chapter02/phone_type.sql: -------------------------------------------------------------------------------- 1 | --This example shows how to create a composite data type. 2 | CREATE TYPE phone_number AS ( 3 | area_code varchar(3), 4 | line_number varchar(7) 5 | ); 6 | CREATE OR REPLACE FUNCTION phone_number_equal (phone_ 7 | number,phone_number) RETURNS boolean AS $$ 8 | BEGIN 9 | IF $1.area_code=$2.area_code AND $1.line_number=$2.line_number THEN 10 | RETURN TRUE ; 11 | ELSE 12 | RETURN FALSE; 13 | END IF; 14 | END; $$ LANGUAGE plpgsql; 15 | CREATE OPERATOR = ( 16 | LEFTARG = phone_number, 17 | RIGHTARG = phone_number, 18 | PROCEDURE = phone_number_equal 19 | ); 20 | --For test purpose 21 | SELECT row('123','222244')::phone_number = row('1','222244')::phone_number; -------------------------------------------------------------------------------- /Chapter03/identity.sql: -------------------------------------------------------------------------------- 1 | CREATE TABLE test_serial (id SERIAL PRIMARY KEY, payload text); 2 | INSERT INTO test_serial (payload) SELECT 'a' RETURNING *; 3 | INSERT INTO test_serial (id, payload) SELECT 2, 'a' RETURNING *; 4 | INSERT INTO test_serial (payload) SELECT 'a' RETURNING *; 5 | 6 | CREATE TABLE test_identity ( id INTEGER generated by default as identity PRIMARY KEY, payload text); 7 | INSERT INTO test_identity (payload) SELECT 'a' RETURNING *; 8 | INSERT INTO test_identity (id, payload) SELECT 1, 'a' RETURNING *; 9 | INSERT INTO test_identity (id, payload) SELECT 100000, 'a' RETURNING *; 10 | 11 | \ds 12 | 13 | CREATE TABLE test_identity2 ( id INTEGER generated always as identity PRIMARY KEY, payload text); 14 | INSERT INTO test_identity2 (id, payload) SELECT 1, 'a' RETURNING *; -------------------------------------------------------------------------------- /Chapter15/Using PostgreSQL in Python applications/psycopg2_copy_data.py: -------------------------------------------------------------------------------- 1 | #!/usr/bin/python3 2 | 3 | from psycopg2 import connect 4 | from io import StringIO 5 | 6 | conn = connect(host="localhost", user="car_portal_app", dbname="car_portal") 7 | 8 | with conn.cursor() as cur, StringIO() as s: 9 | cur.copy_to(table='car_portal_app.car_model', file=s) 10 | print(s.getvalue()) 11 | 12 | 13 | new_records = [ 14 | ["Tesla", "Model X"], 15 | ["Tesla", "Model S"], 16 | ["Tesla", "Model 3"]] 17 | 18 | copy_string = '\n'.join(['\t'.join(record) for record in new_records]) 19 | 20 | with conn.cursor() as cur, StringIO(copy_string) as s: 21 | cur.copy_from(table='car_portal_app.car_model', file=s, 22 | columns=['make', 'model']) 23 | 24 | print("{} records inserted".format(len(new_records))) 25 | 26 | conn.commit() 27 | conn.close() 28 | -------------------------------------------------------------------------------- /Chapter16/Scalability/logical_replication_multi_master/schema.sql: -------------------------------------------------------------------------------- 1 | CREATE ROLE car_portal_app LOGIN; 2 | 3 | DROP DATABASE IF EXISTS car_portal; 4 | 5 | --For linux 6 | CREATE DATABASE car_portal ENCODING 'UTF-8' LC_COLLATE 'en_US.UTF-8' LC_CTYPE 'en_US.UTF-8' TEMPLATE template0 OWNER car_portal_app; 7 | 8 | -- For Windows: 9 | CREATE DATABASE car_portal ENCODING 'UTF-8' LC_COLLATE 'English_United States' LC_CTYPE 'English_United States' TEMPLATE template0 OWNER car_portal_app; 10 | 11 | \c car_portal 12 | 13 | CREATE SCHEMA car_portal_app AUTHORIZATION car_portal_app; 14 | 15 | SET search_path to car_portal_app; 16 | SET ROLE car_portal_app; 17 | 18 | CREATE TABLE car_model 19 | ( 20 | car_model_id INT PRIMARY KEY GENERATED BY DEFAULT AS IDENTITY, 21 | make text NOT NULL, 22 | model text NOT NULL, 23 | CONSTRAINT car_model_uq1 UNIQUE (make, model) 24 | ); 25 | 26 | ALTER TABLE car_model REPLICA IDENTITY USING INDEX car_model_uq1; -------------------------------------------------------------------------------- /Chapter15/Using PostgreSQL in Python applications/asyncpg_raise_notice.py: -------------------------------------------------------------------------------- 1 | #!/usr/bin/python3 2 | 3 | import asyncio 4 | import asyncpg 5 | 6 | 7 | async def main(): 8 | conn = await asyncpg.connect(host='localhost', user='car_portal_app', 9 | database='car_portal') 10 | 11 | conn.add_log_listener(lambda conn, msg: print(msg)) 12 | 13 | print("Executing a command") 14 | await conn.execute(''' 15 | DO $$ 16 | BEGIN 17 | RAISE NOTICE 'Start'; 18 | PERFORM pg_sleep(2); 19 | RAISE NOTICE '1 second'; 20 | PERFORM pg_sleep(2); 21 | RAISE NOTICE '2 second'; 22 | PERFORM pg_sleep(2); 23 | RAISE NOTICE 'Finish'; 24 | END; 25 | $$;''') 26 | print("Finished execution") 27 | 28 | await conn.close() 29 | 30 | asyncio.get_event_loop().run_until_complete(main()) 31 | -------------------------------------------------------------------------------- /Chapter02/file_fdw_log.sql: -------------------------------------------------------------------------------- 1 | CREATE EXTENSION file_fdw ; 2 | CREATE SERVER fileserver FOREIGN DATA WRAPPER file_fdw; 3 | CREATE FOREIGN TABLE postgres_log 4 | ( log_time timestamp(3) with time zone, 5 | user_name text, 6 | database_name text, 7 | process_id integer, 8 | connection_from text, 9 | session_id text, 10 | session_line_num bigint, 11 | command_tag text, 12 | session_start_time timestamp with time zone, 13 | virtual_transaction_id text, 14 | transaction_id bigint, 15 | error_severity text, 16 | sql_state_code text, 17 | message text, 18 | detail text, 19 | hint text, 20 | internal_query text, 21 | internal_query_pos integer, 22 | context text, 23 | query text, 24 | query_pos integer, 25 | location text, 26 | application_name text 27 | ) SERVER fileserver OPTIONS ( filename '/var/lib/postgresql/11/main/log/postgresql.csv', header 'true', format 'csv' ); 28 | SELECT row_to_json(postgres_log, true) FROM postgres_log limit 1; 29 | -------------------------------------------------------------------------------- /Chapter15/Using PostgreSQL in Python applications/psycopg2_pool.py: -------------------------------------------------------------------------------- 1 | #!/usr/bin/python3 2 | 3 | from psycopg2.pool import ThreadedConnectionPool 4 | from multiprocessing.pool import ThreadPool 5 | import time 6 | 7 | 8 | pool = ThreadedConnectionPool(0, 2, host="localhost", user="car_portal_app", 9 | dbname="car_portal") 10 | 11 | queries = ["SELECT 1 FROM pg_sleep(10)", 12 | "SELECT 2 FROM pg_sleep(10)", 13 | "SELECT 3 FROM pg_sleep(10)"] 14 | 15 | 16 | def execute_query(query): 17 | conn = pool.getconn(query) 18 | with conn.cursor() as cur: 19 | cur.execute(query) 20 | row = cur.fetchone() 21 | value = row[0] 22 | pool.putconn(conn, query) 23 | return value 24 | 25 | 26 | thread_pool = ThreadPool(2) 27 | start = time.time() 28 | results = thread_pool.map(execute_query, queries) 29 | end = time.time() 30 | 31 | print(results) 32 | print("The execution took {} seconds".format( 33 | end - start)) 34 | 35 | pool.closeall() 36 | -------------------------------------------------------------------------------- /Chapter15/Using PostgreSQL in Python applications/pg8000_query_data.py: -------------------------------------------------------------------------------- 1 | #!/usr/bin/python3 2 | 3 | from pg8000 import connect 4 | 5 | conn = connect(host="localhost", user="car_portal_app", database="car_portal") 6 | query = "SELECT make, model FROM car_portal_app.car_model" 7 | 8 | print("--- cursor as iterator ---") 9 | with conn.cursor() as cur: 10 | cur.execute(query) 11 | for record in cur: 12 | print("Make: {}, model: {}".format(record[0], record[1])) 13 | 14 | print("--- cursor.fetchone() ---") 15 | with conn.cursor() as cur: 16 | cur.execute(query) 17 | while True: 18 | record = cur.fetchone() 19 | if record is None: 20 | break 21 | print("Make: {}, model: {}".format(record[0], record[1])) 22 | 23 | print("--- cursor.fetchmany() ---") 24 | with conn.cursor() as cur: 25 | cur.execute(query) 26 | while True: 27 | records = cur.fetchmany(10) 28 | if len(records) == 0: 29 | break 30 | print("Set of {} records: {}".format(len(records), str(records))) 31 | 32 | conn.close() 33 | -------------------------------------------------------------------------------- /Chapter15/Using PostgreSQL in Python applications/psycopg2_query_data.py: -------------------------------------------------------------------------------- 1 | #!/usr/bin/python3 2 | 3 | from psycopg2 import connect 4 | 5 | conn = connect(host="localhost", user="car_portal_app", dbname="car_portal") 6 | query = "SELECT make, model FROM car_portal_app.car_model" 7 | 8 | print("--- cursor as iterator ---") 9 | with conn.cursor() as cur: 10 | cur.execute(query) 11 | for record in cur: 12 | print("Make: {}, model: {}".format(record[0], record[1])) 13 | 14 | print("--- cursor.fetchone() ---") 15 | with conn.cursor() as cur: 16 | cur.execute(query) 17 | while True: 18 | record = cur.fetchone() 19 | if record is None: 20 | break 21 | print("Make: {}, model: {}".format(record[0], record[1])) 22 | 23 | print("--- cursor.fetchmany() ---") 24 | with conn.cursor() as cur: 25 | cur.execute(query) 26 | while True: 27 | records = cur.fetchmany(10) 28 | if len(records) == 0: 29 | break 30 | print("Set of {} records: {}".format(len(records), str(records))) 31 | 32 | conn.close() 33 | -------------------------------------------------------------------------------- /Chapter16/Scalability/logical_replication_multi_master/Dockerfile-subscriber: -------------------------------------------------------------------------------- 1 | FROM debian:stretch 2 | 3 | RUN apt-get update 4 | 5 | RUN apt-get install -y wget gnupg locales locales-all 6 | 7 | ENV LC_ALL en_US.UTF-8 8 | ENV LANG en_US.UTF-8 9 | ENV LANGUAGE en_US.UTF-8 10 | 11 | RUN echo "deb http://apt.postgresql.org/pub/repos/apt/ stretch-pgdg main 11" > /etc/apt/sources.list.d/pgdg.list && \ 12 | wget --quiet -O - https://www.postgresql.org/media/keys/ACCC4CF8.asc | apt-key add - && \ 13 | apt-get update 14 | RUN apt-get install -y postgresql-11 15 | 16 | ADD *.sql ./ 17 | 18 | RUN sed -i 's/md5/trust/g' /etc/postgresql/11/main/pg_hba.conf && \ 19 | echo "host all car_portal_app 0.0.0.0/0 trust" >> /etc/postgresql/11/main/pg_hba.conf && \ 20 | echo "listen_addresses = '*'" >> /etc/postgresql/11/main/postgresql.conf && \ 21 | service postgresql start && \ 22 | psql -h localhost -U postgres -f schema.sql && \ 23 | service postgresql stop 24 | 25 | ENTRYPOINT ["su", "-", "postgres", "-c", "/usr/lib/postgresql/11/bin/postgres --config-file=/etc/postgresql/11/main/postgresql.conf"] -------------------------------------------------------------------------------- /LICENSE: -------------------------------------------------------------------------------- 1 | MIT License 2 | 3 | Copyright (c) 2018 Packt 4 | 5 | Permission is hereby granted, free of charge, to any person obtaining a copy 6 | of this software and associated documentation files (the "Software"), to deal 7 | in the Software without restriction, including without limitation the rights 8 | to use, copy, modify, merge, publish, distribute, sublicense, and/or sell 9 | copies of the Software, and to permit persons to whom the Software is 10 | furnished to do so, subject to the following conditions: 11 | 12 | The above copyright notice and this permission notice shall be included in all 13 | copies or substantial portions of the Software. 14 | 15 | THE SOFTWARE IS PROVIDED "AS IS", WITHOUT WARRANTY OF ANY KIND, EXPRESS OR 16 | IMPLIED, INCLUDING BUT NOT LIMITED TO THE WARRANTIES OF MERCHANTABILITY, 17 | FITNESS FOR A PARTICULAR PURPOSE AND NONINFRINGEMENT. IN NO EVENT SHALL THE 18 | AUTHORS OR COPYRIGHT HOLDERS BE LIABLE FOR ANY CLAIM, DAMAGES OR OTHER 19 | LIABILITY, WHETHER IN AN ACTION OF CONTRACT, TORT OR OTHERWISE, ARISING FROM, 20 | OUT OF OR IN CONNECTION WITH THE SOFTWARE OR THE USE OR OTHER DEALINGS IN THE 21 | SOFTWARE. 22 | -------------------------------------------------------------------------------- /Chapter16/Scalability/logical_replication/Dockerfile-subscriber: -------------------------------------------------------------------------------- 1 | FROM debian:stretch 2 | 3 | RUN apt-get update 4 | 5 | RUN apt-get install -y wget gnupg locales locales-all 6 | 7 | ENV LC_ALL en_US.UTF-8 8 | ENV LANG en_US.UTF-8 9 | ENV LANGUAGE en_US.UTF-8 10 | 11 | RUN echo "deb http://apt.postgresql.org/pub/repos/apt/ stretch-pgdg main 11" > /etc/apt/sources.list.d/pgdg.list && \ 12 | wget --quiet -O - https://www.postgresql.org/media/keys/ACCC4CF8.asc | apt-key add - && \ 13 | apt-get update 14 | RUN apt-get install -y postgresql-11 15 | 16 | ADD *.sql ./ 17 | 18 | RUN sed -i 's/md5/trust/g' /etc/postgresql/11/main/pg_hba.conf && \ 19 | echo "host all car_portal_app 0.0.0.0/0 trust" >> /etc/postgresql/11/main/pg_hba.conf && \ 20 | echo "listen_addresses = '*'" >> /etc/postgresql/11/main/postgresql.conf && \ 21 | service postgresql start && \ 22 | psql -h localhost -U postgres -f schema.sql && \ 23 | service postgresql stop 24 | 25 | VOLUME /etc/postgresql/11/main 26 | VOLUME /var/lib/postgresql/11/main 27 | 28 | ENTRYPOINT ["su", "-", "postgres", "-c", "/usr/lib/postgresql/11/bin/postgres --config-file=/etc/postgresql/11/main/postgresql.conf"] -------------------------------------------------------------------------------- /Chapter09/hstore.sql: -------------------------------------------------------------------------------- 1 | CREATE EXTENSION hstore; 2 | SELECT 'tires=>"winter tires", seat=>leather'::hstore; 3 | SELECT hstore('Hello', 'World'); 4 | SELECT 'a=>1, a=>2'::hstore; 5 | 6 | ALTER TABLE car_portal_app.car ADD COLUMN features hstore; 7 | SELECT 'color=>red, Color=>blue'::hstore; 8 | 9 | CREATE TABLE features ( 10 | features hstore 11 | ); 12 | 13 | 14 | INSERT INTO features (features) VALUES ('Engine=>Diesel'::hstore) RETURNING *; 15 | -- To add a new key 16 | UPDATE features SET features = features || hstore ('Seat', 'Lethear') RETURNING *; 17 | -- To update a key, this is similar to add a key 18 | UPDATE features SET features = features || hstore ('Engine', 'Petrol') RETURNING *; 19 | -- To delete a key 20 | UPDATE features SET features = features - 'Seat'::TEXT RETURNING *; 21 | SELECT DISTINCT (each(features)).key FROM features; 22 | SELECT (each(features)).* FROM features; 23 | 24 | 25 | CREATE INDEX ON features USING GIN (features); 26 | SET enable_seqscan to off; 27 | EXPLAIN SELECT features->'Engine' FROM features WHERE features ? 'Engine'; 28 | 29 | CREATE INDEX ON features ((features->'Engine')); 30 | EXPLAIN SELECT features->'Engine' FROM features WHERE features->'Engine'= 'Diesel'; -------------------------------------------------------------------------------- /Chapter16/Scalability/streaming_replication/Dockerfile-standby: -------------------------------------------------------------------------------- 1 | FROM debian:stretch 2 | 3 | RUN apt-get update 4 | 5 | RUN apt-get install -y wget gnupg locales locales-all 6 | 7 | ENV LC_ALL en_US.UTF-8 8 | ENV LANG en_US.UTF-8 9 | ENV LANGUAGE en_US.UTF-8 10 | 11 | RUN echo "deb http://apt.postgresql.org/pub/repos/apt/ stretch-pgdg main 11" > /etc/apt/sources.list.d/pgdg.list && \ 12 | wget --quiet -O - https://www.postgresql.org/media/keys/ACCC4CF8.asc | apt-key add - && \ 13 | apt-get update 14 | RUN apt-get install -y postgresql-11 15 | 16 | ADD *.sql ./ 17 | ADD recovery.conf /var/lib/postgresql/11/main/ 18 | 19 | RUN chown postgres:postgres /var/lib/postgresql/11/main/recovery.conf 20 | 21 | RUN sed -i 's/md5/trust/g' /etc/postgresql/11/main/pg_hba.conf && \ 22 | echo "host all car_portal_app 0.0.0.0/0 trust" >> /etc/postgresql/11/main/pg_hba.conf && \ 23 | echo "listen_addresses = '*'" >> /etc/postgresql/11/main/postgresql.conf && \ 24 | service postgresql start && \ 25 | service postgresql stop 26 | 27 | VOLUME /etc/postgresql/11/main 28 | VOLUME /var/lib/postgresql/11/main 29 | 30 | ENTRYPOINT ["su", "-", "postgres", "-c", "/usr/lib/postgresql/11/bin/postgres --config-file=/etc/postgresql/11/main/postgresql.conf"] -------------------------------------------------------------------------------- /Chapter09/text_search.sql: -------------------------------------------------------------------------------- 1 | SELECT 'A wise man always has something to say, whereas a fool always needs to say something'::tsvector; 2 | SELECT to_tsvector('english', 'A wise man always has something to say, whereas a fool always needs to say something'); 3 | SHOW default_text_search_config; 4 | 5 | SELECT 'A wise man always has something to say, whereas a fool always needs to say something'::tsvector @@ 'wise'::tsquery; 6 | SELECT to_tsquery('english', 'wise & man'), plainto_tsquery('english', 'wise man'); 7 | SELECT to_tsvector('A wise man always has something to say, whereas a fool always needs to say something') @@ to_tsquery('wise <-> man'); 8 | 9 | SELECT 'elephants'::tsvector @@ 'elephant'; 10 | SELECT to_tsvector('english', 'elephants') @@ to_tsquery('english', 'elephant'); 11 | SELECT to_tsvector('simple', 'elephants') @@ to_tsquery('simple', 'elephant'); 12 | SELECT setweight(to_tsvector('english', 'elephants'),'A') || setweight(to_tsvector('english', 'dolphin'),'B'); 13 | 14 | SELECT ts_rank_cd (setweight(to_tsvector('english','elephants'),'A') || setweight(to_tsvector('english', 'dolphin'),'B'),'eleph' ); 15 | SELECT ts_rank_cd (setweight(to_tsvector('english','elephants'),'A') || setweight(to_tsvector('english', 'dolphin'),'B'),'dolphin' ); -------------------------------------------------------------------------------- /Chapter16/Scalability/logical_replication_multi_master/Dockerfile-publisher: -------------------------------------------------------------------------------- 1 | FROM debian:stretch 2 | 3 | RUN apt-get update 4 | 5 | RUN apt-get install -y wget gnupg locales locales-all 6 | 7 | ENV LC_ALL en_US.UTF-8 8 | ENV LANG en_US.UTF-8 9 | ENV LANGUAGE en_US.UTF-8 10 | 11 | RUN echo "deb http://apt.postgresql.org/pub/repos/apt/ stretch-pgdg main 11" > /etc/apt/sources.list.d/pgdg.list && \ 12 | wget --quiet -O - https://www.postgresql.org/media/keys/ACCC4CF8.asc | apt-key add - && \ 13 | apt-get update 14 | RUN apt-get install -y postgresql-11 15 | 16 | ADD *.sql ./ 17 | 18 | RUN sed -i 's/md5/trust/g' /etc/postgresql/11/main/pg_hba.conf && \ 19 | echo "host all car_portal_app 0.0.0.0/0 trust" >> /etc/postgresql/11/main/pg_hba.conf && \ 20 | echo "listen_addresses = '*'" >> /etc/postgresql/11/main/postgresql.conf && \ 21 | echo "wal_level = logical" >> /etc/postgresql/11/main/postgresql.conf && \ 22 | service postgresql start && \ 23 | psql -h localhost -U postgres -f schema.sql && \ 24 | psql -h localhost -U car_portal_app -d car_portal -f data.sql -1 && \ 25 | psql -h localhost -U postgres -d car_portal -f publisher.sql && \ 26 | service postgresql stop 27 | 28 | ENTRYPOINT ["su", "-", "postgres", "-c", "/usr/lib/postgresql/11/bin/postgres --config-file=/etc/postgresql/11/main/postgresql.conf"] -------------------------------------------------------------------------------- /Chapter04/sql_examples/rule.sql: -------------------------------------------------------------------------------- 1 | CREATE TABLE car_portal_app.car_log (LIKE car_portal_app.car); 2 | ALTER TABLE car_portal_app.car_log ADD COLUMN car_log_action varchar (1) NOT NULL, ADD COLUMN car_log_time TIMESTAMP WITH TIME ZONE NOT NULL; 3 | GRANT ALL ON car_portal_app.car_log to car_portal_app; 4 | 5 | CREATE RULE car_log AS ON INSERT TO car_portal_app.car DO ALSO 6 | INSERT INTO car_portal_app.car_log (car_id, car_model_id, number_of_owners, registration_number, number_of_doors, manufacture_year,car_log_action, car_log_time) 7 | VALUES (new.car_id, new.car_model_id,new.number_of_owners, new.registration_number, new.number_of_doors, new.manufacture_year,'I', now()); 8 | 9 | INSERT INTO car_portal_app.car (car_id, car_model_id, number_of_owners, registration_number, number_of_doors, manufacture_year) VALUES (100000, 2, 2, 'x', 3, 2017); 10 | SELECT to_json(car) FROM car_portal_app.car where registration_number ='x'; 11 | SELECT to_json(car_log) FROM car_portal_app.car_log where registration_number ='x'; 12 | 13 | INSERT INTO car_portal_app.car (car_id, car_model_id, number_of_owners, registration_number, number_of_doors, manufacture_year) VALUES (default, 2, 2, 'y', 3, 2017); 14 | SELECT to_json(car) FROM car_portal_app.car where registration_number ='y'; 15 | SELECT to_json(car_log) FROM car_portal_app.car_log where registration_number ='y'; -------------------------------------------------------------------------------- /Chapter16/Scalability/logical_replication/Dockerfile-publisher: -------------------------------------------------------------------------------- 1 | FROM debian:stretch 2 | 3 | RUN apt-get update 4 | 5 | RUN apt-get install -y wget gnupg locales locales-all 6 | 7 | ENV LC_ALL en_US.UTF-8 8 | ENV LANG en_US.UTF-8 9 | ENV LANGUAGE en_US.UTF-8 10 | 11 | RUN echo "deb http://apt.postgresql.org/pub/repos/apt/ stretch-pgdg main 11" > /etc/apt/sources.list.d/pgdg.list && \ 12 | wget --quiet -O - https://www.postgresql.org/media/keys/ACCC4CF8.asc | apt-key add - && \ 13 | apt-get update 14 | RUN apt-get install -y postgresql-11 15 | 16 | ADD *.sql ./ 17 | 18 | RUN sed -i 's/md5/trust/g' /etc/postgresql/11/main/pg_hba.conf && \ 19 | echo "host all car_portal_app 0.0.0.0/0 trust" >> /etc/postgresql/11/main/pg_hba.conf && \ 20 | echo "listen_addresses = '*'" >> /etc/postgresql/11/main/postgresql.conf && \ 21 | echo "wal_level = logical" >> /etc/postgresql/11/main/postgresql.conf && \ 22 | service postgresql start && \ 23 | psql -h localhost -U postgres -f schema.sql && \ 24 | psql -h localhost -U car_portal_app -d car_portal -f data.sql -1 && \ 25 | psql -h localhost -U postgres -d car_portal -f publisher.sql && \ 26 | service postgresql stop 27 | 28 | VOLUME /etc/postgresql/11/main 29 | VOLUME /var/lib/postgresql/11/main 30 | 31 | ENTRYPOINT ["su", "-", "postgres", "-c", "/usr/lib/postgresql/11/bin/postgres --config-file=/etc/postgresql/11/main/postgresql.conf"] -------------------------------------------------------------------------------- /Chapter15/Using PostgreSQL in Python applications/sqlalchemy_sql_expression_language.py: -------------------------------------------------------------------------------- 1 | #!/usr/bin/python3 2 | 3 | from sqlalchemy import * 4 | 5 | engine = create_engine( 6 | "postgresql+pg8000://car_portal_app@localhost/car_portal", 7 | echo=True) 8 | 9 | metadata = MetaData() 10 | 11 | # Defining the table car_model explicitly 12 | car_model = Table( 13 | 'car_model', metadata, 14 | Column('car_model_id', Integer, primary_key=True), 15 | Column('make', String), 16 | Column('model', String), 17 | schema='car_portal_app') 18 | 19 | # Loading the definition of the table car from the database 20 | car = Table('car', metadata, schema='car_portal_app', 21 | autoload=True, autoload_with=engine) 22 | 23 | # Print the names of the columns of the table car 24 | for column in car.columns: 25 | print(column) 26 | 27 | # Obtaining a database connection 28 | conn = engine.connect() 29 | 30 | # Query car models 31 | query = select([car_model]) 32 | result = conn.execute(query) 33 | for row in result: 34 | print(row) 35 | 36 | # Create a new car model 37 | ins = car_model.insert() 38 | conn.execute(ins, [ 39 | {'make': 'Jaguar', 'model': 'XF'}, 40 | {'make': 'Jaguar', 'model': 'XJ'}]) 41 | print(ins) 42 | 43 | # Query the new model 44 | query = select([car_model]).where(car_model.c.make == "Jaguar") 45 | for record in conn.execute(query): 46 | print(record) 47 | -------------------------------------------------------------------------------- /Chapter12/get_unused_index.sql: -------------------------------------------------------------------------------- 1 | 2 | SELECT schemaname, relname, indexrelname FROM pg_stat_user_indexes s JOIN pg_index i ON s.indexrelid = i.indexrelid WHERE idx_scan=0 AND NOT indisunique AND NOT indisprimary; 3 | 4 | CREATE TABLE test_index_overlap(a int, b int); 5 | CREATE INDEX ON test_index_overlap (a,b); 6 | CREATE INDEX ON test_index_overlap (b,a); 7 | 8 | WITH index_info AS ( 9 | SELECT 10 | pg_get_indexdef(indexrelid) AS index_def, 11 | indexrelid::regclass 12 | index_name , 13 | indrelid::regclass table_name, array_agg(attname order by attnum) AS index_att 14 | FROM 15 | pg_index i JOIN 16 | pg_attribute a ON i.indexrelid = a.attrelid 17 | GROUP BY 18 | pg_get_indexdef(indexrelid), indrelid, indexrelid 19 | ) SELECT DISTINCT 20 | CASE WHEN a.index_name > b.index_name THEN a.index_def ELSE b.index_def END AS index_def, 21 | CASE WHEN a.index_name > b.index_name THEN a.index_name ELSE b.index_name END AS index_name, 22 | CASE WHEN a.index_name > b.index_name THEN b.index_def ELSE a.index_def END AS overlap_index_def, 23 | CASE WHEN a.index_name > b.index_name THEN b.index_name ELSE a.index_name END AS overlap_index_name, 24 | a.index_att = b.index_att as full_match, 25 | a.table_name 26 | FROM 27 | index_info a INNER JOIN 28 | index_info b ON (a.index_name != b.index_name AND a.table_name = b.table_name AND a.index_att && b.index_att ); 29 | 30 | -------------------------------------------------------------------------------- /Chapter09/json.sql: -------------------------------------------------------------------------------- 1 | WITH test_data(pi) AS (SELECT '{"pi":"3.14", "pi":"3.14" }') SELECT pi::JSON, pi::JSONB FROM test_data; 2 | SELECT '{"name":"John", "Address":{"Street":"Some street", "city":"Some city"}, "rank":[5,3,4,5,2,3,4,5]}'::JSONB; 3 | 4 | CREATE TABLE json_doc ( doc jsonb ); 5 | INSERT INTO json_doc SELECT '{"name":"John", "Address":{"Street":"Some street", "city":"Some city"}, "rank":[5,3,4,5,2,3,4,5]}'::JSONB ; 6 | 7 | SELECT doc->'Address'->>'city', doc#>>'{Address, city}' FROM json_doc WHERE doc->>'name' = 'John'; 8 | 9 | 10 | SELECT (regexp_replace(doc::text, '"rank":(.*)],',''))::jsonb FROM json_doc WHERE doc->>'name' = 'John'; 11 | 12 | update json_doc SET doc = jsonb_insert(doc, '{hobby}','["swim", "read"]', true) RETURNING * ; 13 | update json_doc SET doc = jsonb_set(doc, '{hobby}','["read"]', true) RETURNING * ; 14 | update json_doc SET doc = doc -'hobby' RETURNING * ; 15 | 16 | CREATE INDEX ON json_doc(doc); 17 | SET enable_seqscan = off; 18 | 19 | EXPLAIN SELECT * FROM json_doc WHERE doc @> '{"name":"John"}'; 20 | 21 | 22 | SELECT to_json (row(account_id,first_name, last_name, email)) FROM car_portal_app.account LIMIT 1; 23 | SELECT to_json (account) FROM car_portal_app.account LIMIT 1; 24 | 25 | WITH account_info(account_id, first_name, last_name, email) AS ( SELECT account_id,first_name, last_name, email FROM car_portal_app. account LIMIT 1 26 | ) SELECT to_json(account_info) FROM account_info; -------------------------------------------------------------------------------- /Chapter12/get_view_dependency.sql: -------------------------------------------------------------------------------- 1 | CREATE TABLE test_view_dep AS SELECT 1; 2 | CREATE VIEW a AS SELECT 1 FROM test_view_dep; 3 | CREATE VIEW b AS SELECT 1 FROM a; 4 | CREATE VIEW c AS SELECT 1 FROM a; 5 | CREATE VIEW d AS SELECT 1 FROM b,c; 6 | CREATE VIEW e AS SELECT 1 FROM c; 7 | CREATE VIEW f AS SELECT 1 FROM d,c; 8 | 9 | CREATE OR REPLACE FUNCTION get_dependency (schema_name text, view_name text) RETURNS TABLE (schema_name text, view_name text, level int) AS $$ 10 | WITH RECURSIVE view_tree(parent_schema, parent_view, child_schema, child_view, level) as 11 | ( 12 | SELECT parent.view_schema, parent.view_name ,parent.table_schema, parent.table_name, 1 13 | FROM information_schema.view_table_usage parent 14 | WHERE parent.view_schema = $1 AND parent.view_name = $2 15 | UNION ALL 16 | SELECT child.view_schema, child.view_name, child.table_schema, child.table_name, parent.level + 1 17 | FROM view_tree parent JOIN information_schema.view_table_usage child ON child.table_schema = parent.parent_schema AND child.table_name = parent.parent_view 18 | ) 19 | SELECT DISTINCT 20 | parent_schema, parent_view, level 21 | FROM ( 22 | SELECT parent_schema, parent_view, max (level) OVER (PARTITION BY parent_schema, parent_view) as max_level,level 23 | FROM view_tree) AS FOO 24 | WHERE level = max_level 25 | ORDER BY 3 ASC; 26 | $$ 27 | LANGUAGE SQL; 28 | 29 | SELECT * FROM get_dependency('public', 'a'); 30 | -------------------------------------------------------------------------------- /Chapter04/sql_examples/function.sql: -------------------------------------------------------------------------------- 1 | CREATE OR REPLACE FUNCTION is_updatable_view (text) RETURNS BOOLEAN AS $$ 2 | SELECT is_insertable_into='YES' FROM information_schema.tables WHERE table_type = 'VIEW' AND table_name = $1 3 | $$ LANGUAGE SQL; 4 | 5 | CREATE FUNCTION drop_table (text) RETURNS VOID AS $$ 6 | DROP TABLE $1; 7 | $$ LANGUAGE SQL; 8 | 9 | CREATE OR REPLACE FUNCTION fact(fact INT) RETURNS INT AS $$ 10 | DECLARE 11 | count INT = 1; 12 | result INT = 1; 13 | BEGIN 14 | FOR count IN 1..fact LOOP 15 | result = result* count; 16 | END LOOP; 17 | RETURN result; 18 | END; 19 | $$ LANGUAGE plpgsql; 20 | 21 | 22 | CREATE OR REPLACE FUNCTION test_dep (INT) RETURNS INT AS $$ 23 | BEGIN 24 | RETURN $1; 25 | END; 26 | $$ 27 | LANGUAGE plpgsql; 28 | CREATE OR REPLACE FUNCTION test_dep_2(INT) RETURNS INT AS $$ 29 | BEGIN 30 | RETURN test_dep($1); 31 | END; 32 | $$ 33 | LANGUAGE plpgsql; 34 | 35 | DROP FUNCTION test_dep(int); 36 | 37 | SELECT test_dep_2 (5); 38 | 39 | BEGIN; 40 | SELECT now();S 41 | SELECT 'Some time has passed', now(); 42 | 43 | CREATE user select_only;S 44 | DO $$ 45 | DECLARE r record; 46 | BEGIN 47 | FOR r IN SELECT table_schema, table_name FROM information_schema.tables WHERE table_schema = 'car_portal_app' LOOP 48 | EXECUTE 'GRANT SELECT ON ' || quote_ident(r.table_schema) || '.'|| quote_ident(r.table_name) || ' TO select_only'; 49 | END LOOP; 50 | END$$; 51 | -------------------------------------------------------------------------------- /Chapter16/Scalability/streaming_replication/Dockerfile-master: -------------------------------------------------------------------------------- 1 | FROM debian:stretch 2 | 3 | RUN apt-get update 4 | 5 | RUN apt-get install -y wget gnupg locales locales-all 6 | 7 | ENV LC_ALL en_US.UTF-8 8 | ENV LANG en_US.UTF-8 9 | ENV LANGUAGE en_US.UTF-8 10 | 11 | RUN echo "deb http://apt.postgresql.org/pub/repos/apt/ stretch-pgdg main 11" > /etc/apt/sources.list.d/pgdg.list && \ 12 | wget --quiet -O - https://www.postgresql.org/media/keys/ACCC4CF8.asc | apt-key add - && \ 13 | apt-get update 14 | RUN apt-get install -y postgresql-11 15 | 16 | ADD *.sql ./ 17 | 18 | RUN sed -i 's/md5/trust/g' /etc/postgresql/11/main/pg_hba.conf && \ 19 | echo "host all car_portal_app 0.0.0.0/0 trust" >> /etc/postgresql/11/main/pg_hba.conf && \ 20 | echo "host replication streamer 0.0.0.0/0 trust" >> /etc/postgresql/11/main/pg_hba.conf && \ 21 | echo "listen_addresses = '*'" >> /etc/postgresql/11/main/postgresql.conf && \ 22 | echo "wal_level = replica" >> /etc/postgresql/11/main/postgresql.conf && \ 23 | echo "max_wal_senders = 1" >> /etc/postgresql/11/main/postgresql.conf && \ 24 | echo "max_replication_slots = 1" >> /etc/postgresql/11/main/postgresql.conf && \ 25 | service postgresql start && \ 26 | psql -h localhost -U postgres -f master.sql && \ 27 | service postgresql stop && \ 28 | echo "synchronous_standby_names = 'standby1'" >> /etc/postgresql/11/main/postgresql.conf 29 | 30 | VOLUME /etc/postgresql/11/main 31 | VOLUME /var/lib/postgresql/11/main 32 | 33 | ENTRYPOINT ["su", "-", "postgres", "-c", "/usr/lib/postgresql/11/bin/postgres --config-file=/etc/postgresql/11/main/postgresql.conf"] -------------------------------------------------------------------------------- /Chapter04/sql_examples/view.sql: -------------------------------------------------------------------------------- 1 | CREATE VIEW test AS 2 | SELECT 1 as v; 3 | 4 | CREATE VIEW test2 AS 5 | SELECT v FROM test; 6 | 7 | CREATE OR REPLACE VIEW test AS 8 | SELECT 1 as val; 9 | 10 | CREATE VIEW car_portal_app.account_information AS 11 | SELECT account_id, first_name, last_name, email FROM car_portal_app.account; 12 | \d car_portal_app.account_information 13 | 14 | CREATE OR REPLACE VIEW car_portal_app.account_information (account_id,first_name,last_name,email) AS 15 | SELECT account_id, first_name, last_name, email FROM car_portal_app.account; 16 | 17 | CREATE OR REPLACE VIEW car_portal_app.account_information AS 18 | SELECT account_id, last_name, first_name, email FROM car_portal_app.account; 19 | 20 | CREATE MATERIALIZED VIEW test_mat AS 21 | SELECT 1 WITH NO DATA; 22 | TABLE test_mat; 23 | REFRESH MATERIALIZED VIEW test_mat; 24 | TABLE test_mat; 25 | 26 | CREATE OR REPLACE VIEW car_portal_app.user_account AS 27 | SELECT account_id, first_name, last_name, email, password 28 | FROM car_portal_app.account 29 | WHERE account_id NOT IN (SELECT account_id FROM car_portal_app.seller_account); 30 | 31 | INSERT INTO car_portal_app.user_account VALUES (default,'first_name1','last_name1','test1@email.com','password'); 32 | 33 | WITH account_info AS ( 34 | INSERT INTO car_portal_app.user_account VALUES (default,'first_name2','last_name2','test2@email.com','password') RETURNING account_id 35 | ) INSERT INTO car_portal_app.seller_account (account_id, street_name, street_number, zip_code, city) SELECT account_id, 'street1', '555', '555', 'test_city' FROM account_info; 36 | 37 | DELETE FROM user_account WHERE first_name = 'first_name2'; 38 | 39 | CREATE TABLE check_option (val INT); 40 | CREATE VIEW test_check_option AS SELECT * FROM check_option WHERE val > 0 WITH CHECK OPTION; 41 | INSERT INTO test_check_option VALUES (-1); 42 | 43 | SELECT table_name, is_insertable_into FROM information_schema.tables WHERE table_name = 'user_account'; 44 | 45 | -------------------------------------------------------------------------------- /Chapter04/sql_examples/user_data_type.sql: -------------------------------------------------------------------------------- 1 | CREATE DOMAIN text_without_space_and_null AS TEXT NOT NULL CHECK (value!~ '\s'); 2 | CREATE TABLE test_domain ( 3 | test_att text_without_space_and_null 4 | ); 5 | 6 | INSERT INTO test_domain values ('hello'); 7 | INSERT INTO test_domain values ('hello world'); 8 | INSERT INTO test_domain values (null); 9 | 10 | CREATE SEQUENCE global_id_seq; 11 | CREATE DOMAIN global_serial INT DEFAULT NEXTVAL('global_id_seq') NOT NULL; 12 | 13 | 14 | ALTER DOMAIN text_without_space_and_null ADD CONSTRAINT text_without_space_and_null_length_chk check (length(value)<=15); 15 | 16 | ALTER DOMAIN text_without_space_and_null ADD CONSTRAINT text_without_ space_and_null_length_chk check (length(value)<=15) NOT VALID; 17 | 18 | CREATE TYPE car_portal_app.seller_information AS (seller_id INT, seller_name TEXT,number_of_advertisements BIGINT, total_rank float); 19 | 20 | CREATE OR REPLACE FUNCTION car_portal_app.seller_information (account_id INT ) RETURNS car_portal_app.seller_information AS $$ 21 | SELECT seller_account.seller_account_id, first_name || last_name as seller_name, count(*), sum(rank)::float/count(*) 22 | FROM car_portal_app.account INNER JOIN 23 | car_portal_app.seller_account ON account.account_id = seller_account.account_id LEFT JOIN 24 | car_portal_app.advertisement ON advertisement.seller_account_id = seller_account.seller_account_id LEFT JOIN 25 | car_portal_app.advertisement_rating ON advertisement.advertisement_id = advertisement_rating.advertisement_id 26 | WHERE account.account_id = $1 27 | GROUP BY seller_account.seller_account_id, first_name, last_name 28 | $$ 29 | LANGUAGE SQL; 30 | 31 | 32 | CREATE TABLE rank ( 33 | rank_id SERIAL PRIMARY KEY, 34 | rank_name TEXT NOT NULL 35 | ); 36 | INSERT INTO rank VALUES (1, 'poor') , (2, 'fair'), (3, 'good') , (4,'very good') ,( 5, 'excellent'); 37 | 38 | CREATE TYPE rank AS ENUM ('poor', 'fair', 'good', 'very good','excellent'); 39 | SELECT enum_range(null::rank); 40 | SELECT unnest(enum_range(null::rank)) order by 1 desc; 41 | -------------------------------------------------------------------------------- /Chapter15/Using PostgreSQL in Python applications/sqlalchemy_orm.py: -------------------------------------------------------------------------------- 1 | #!/usr/bin/python3 2 | 3 | from sqlalchemy import * 4 | from sqlalchemy.ext.declarative import declarative_base 5 | from sqlalchemy.orm import sessionmaker, relationship 6 | 7 | engine = create_engine( 8 | "postgresql+pg8000://car_portal_app@localhost/car_portal", 9 | echo=False) 10 | 11 | Base = declarative_base() 12 | Session = sessionmaker(bind=engine) 13 | 14 | 15 | class Car_model(Base): 16 | __tablename__ = "car_model" 17 | __table_args__ = {'schema': 'car_portal_app'} 18 | 19 | car_model_id = Column(Integer, primary_key=True) 20 | make = Column(String) 21 | model = Column(String) 22 | 23 | 24 | class Car(Base): 25 | __tablename__ = "car" 26 | __table_args__ = {'schema': 'car_portal_app'} 27 | 28 | car_id = Column(Integer, primary_key=True) 29 | number_of_owners = Column(Integer, nullable=False) 30 | registration_number = Column(String, nullable=False) 31 | manufacture_year = Column(Integer, nullable=False) 32 | number_of_doors = Column(Integer, nullable=False) 33 | car_model_id = Column(Integer, ForeignKey(Car_model.car_model_id), 34 | nullable=False) 35 | mileage = Column(Integer) 36 | car_model = relationship(Car_model) 37 | 38 | def __repr__(self): 39 | car_text = ("Car: ID={}, {} {}, Registration plate: '{}', " 40 | "Number of owners: {}, Manufacture year: {}, " 41 | "Number of doors: {}".format( 42 | self.car_id, self.car_model.make, self.car_model.model, 43 | self.registration_number, 44 | self.number_of_owners, self.manufacture_year, 45 | self.number_of_doors)) 46 | if self.mileage is not None: 47 | car_text = car_text + ", Mileage: {}".format(self.mileage) 48 | return car_text 49 | 50 | 51 | # Query cars 52 | session = Session() 53 | 54 | query = session.query(Car).order_by(Car.car_id).limit(5) 55 | for car in query.all(): 56 | print(car) 57 | 58 | # Update a car 59 | car = query.first() 60 | car.registration_number = 'BOND007' 61 | print(query.first()) 62 | 63 | session.commit() 64 | session.close() 65 | 66 | # Create a new car model 67 | new_car_model = Car_model(make="Jaguar", model="XE") 68 | session = Session() 69 | session.add(new_car_model) 70 | session.commit() 71 | print("Created {} {}".format(new_car_model.make, new_car_model.model)) 72 | session.close() 73 | 74 | # Delete a car model 75 | session = Session() 76 | old_car_model = session.query(Car_model).filter( 77 | and_(Car_model.make == "Jaguar", Car_model.model == "XE")).one() 78 | session.delete(old_car_model) 79 | session.commit() 80 | print("Removed {} {}".format(new_car_model.make, new_car_model.model)) 81 | session.close() 82 | -------------------------------------------------------------------------------- /Chapter09/array.sql: -------------------------------------------------------------------------------- 1 | SELECT ('{red, green, blue}'::text[])[1] as red ; 2 | 3 | WITH arr AS (SELECT '[0:1]={1,2}'::INT[] as arr) SELECT arr, arr[0]; 4 | 5 | SELECT array['red','green','blue'] AS primary_colors; 6 | 7 | SELECT 8 | array_ndims(two_dim_array) AS "Number of dimensions", 9 | array_dims(two_dim_array) AS "Dimensions index range", 10 | array_length(two_dim_array, 1) AS "The array length of 1st dimension", 11 | cardinality(two_dim_array) AS "Number of elements", 12 | two_dim_array[1][1] AS "The first element" 13 | FROM 14 | (VALUES ('{{red,green,blue}, {red,green,blue}}'::text[][])) AS foo(two_dim_array); 15 | 16 | SELECT tablename, attname, most_common_vals, most_common_freqs FROM pg_stats WHERE array_length(most_common_vals,1) < 10 AND schemaname NOT IN ('pg_catalog','information_schema') LIMIT 1; 17 | 18 | CREATE OR REPLACE FUNCTION null_count (VARIADIC arr int[]) RETURNS INT AS 19 | $$ 20 | SELECT count(CASE WHEN m IS NOT NULL THEN 1 ELSE NULL END)::int FROM unnest($1) m(n) 21 | $$ LANGUAGE SQL; 22 | 23 | 24 | CREATE TABLE car ( 25 | car_id SERIAL PRIMARY KEY, 26 | car_number_of_doors INT DEFAULT 5 27 | ); 28 | CREATE TABLE bus ( 29 | bus_id SERIAL PRIMARY KEY, 30 | bus_number_of_passengers INT DEFAULT 50 31 | ); 32 | CREATE TABLE vehicle ( 33 | vehicle_id SERIAL PRIMARY KEY, 34 | registration_number TEXT, 35 | car_id INT REFERENCES car(car_id), 36 | bus_id INT REFERENCES bus(bus_id), 37 | CHECK (null_count(car_id, bus_id) = 1) 38 | ); 39 | 40 | INSERT INTO public.vehicle VALUES (default, 'a234', null, null); 41 | INSERT INTO public.vehicle VALUES (default, 'a234', 1, 1); 42 | INSERT INTO public.vehicle VALUES (default, 'a234', null, 1); 43 | INSERT INTO public.vehicle VALUES (default, 'a234', 1, null); 44 | 45 | SELECT * FROM null_count(VARIADIC ARRAY [null, 1]); 46 | 47 | 48 | CREATE TABLE prefix ( 49 | network TEXT, 50 | prefix_code TEXT NOT NULL 51 | ); 52 | INSERT INTO prefix VALUES ('Palestine Jawwal', 97059), ('Palestine Jawwal',970599), ('Palestine watania',970597); 53 | 54 | CREATE OR REPLACE FUNCTION prefixes(TEXT) RETURNS TEXT[] AS $$ 55 | SELECT ARRAY(SELECT substring($1,1,i) FROM generate_series(1,length($1)) g(i))::TEXT[]; 56 | $$ LANGUAGE SQL IMMUTABLE; 57 | 58 | SELECT * FROM prefix WHERE prefix_code = any (prefixes('97059973456789')) ORDER BY length(prefix_code) DESC limit 1; 59 | 60 | SELECT array(SELECT DISTINCT unnest (array [1,1,1,2,3,3]) ORDER BY 1); 61 | 62 | SELECT make, array_agg(model) FROM car_model group by make; 63 | 64 | SELECT 1 in (1,2,3), 1 = ANY ('{1,2,3}'::INT[]); 65 | 66 | CREATE TABLE color( 67 | color text [] 68 | ); 69 | 70 | INSERT INTO color(color) VALUES ('{red, green}'::text[]); 71 | INSERT INTO color(color) VALUES ('{red}'::text[]); 72 | 73 | SELECT color [3]IS NOT DISTINCT FROM null FROM color; 74 | 75 | SELECT color [1:2] FROM color; 76 | 77 | SELECT ARRAY ['red', 'green'] || '{blue}'::text[] AS append; 78 | UPDATE color SET color[1:2] = '{black, white}'; 79 | SELECT array_remove ('{Hello, Hello, World}'::TEXT[], 'Hello'); 80 | 81 | SELECT ARRAY(SELECT unnest FROM unnest ('{Hello1, Hello2, World}'::TEXT[]) WITH ordinality WHERE ordinality <> 1); 82 | 83 | CREATE INDEX ON color USING GIN (color); 84 | SET enable_seqscan TO off; 85 | EXPLAIN SELECT * FROM color WHERE '{red}'::text[] && color; -------------------------------------------------------------------------------- /Chapter14/Testing/schema.sql: -------------------------------------------------------------------------------- 1 | -- This should be executed using psql. 2 | 3 | CREATE ROLE car_portal_app LOGIN; 4 | 5 | DROP DATABASE IF EXISTS car_portal; 6 | 7 | --For linux 8 | CREATE DATABASE car_portal ENCODING 'UTF-8' LC_COLLATE 'en_US.UTF-8' LC_CTYPE 'en_US.UTF-8' TEMPLATE template0 OWNER car_portal_app; 9 | 10 | -- For Windows: 11 | -- CREATE DATABASE car_portal ENCODING 'UTF-8' LC_COLLATE 'English_United States' LC_CTYPE 'English_United States' TEMPLATE template0 OWNER car_portal_app; 12 | 13 | \c car_portal 14 | 15 | CREATE SCHEMA car_portal_app AUTHORIZATION car_portal_app; 16 | 17 | SET search_path to car_portal_app; 18 | SET ROLE car_portal_app; 19 | 20 | CREATE TABLE account ( 21 | account_id INT PRIMARY KEY GENERATED BY DEFAULT AS IDENTITY, 22 | first_name TEXT NOT NULL, 23 | last_name TEXT NOT NULL, 24 | email TEXT NOT NULL UNIQUE, 25 | password TEXT NOT NULL, 26 | CHECK(first_name !~ '\s' AND last_name !~ '\s'), 27 | CHECK (email ~* '^\w+@\w+[.]\w+$'), 28 | CHECK (char_length(password)>=8) 29 | ); 30 | 31 | CREATE TABLE account_history ( 32 | account_history_id BIGINT PRIMARY KEY GENERATED BY DEFAULT AS IDENTITY, 33 | account_id INT NOT NULL REFERENCES account(account_id), 34 | search_key TEXT NOT NULL, 35 | search_date DATE NOT NULL, 36 | UNIQUE (account_id, search_key, search_date) 37 | ); 38 | 39 | CREATE TABLE seller_account ( 40 | seller_account_id INT PRIMARY KEY GENERATED BY DEFAULT AS IDENTITY, 41 | account_id INT NOT NULL REFERENCES account(account_id), 42 | total_rank FLOAT, 43 | number_of_advertisement INT, 44 | street_name TEXT NOT NULL, 45 | street_number TEXT NOT NULL, 46 | zip_code TEXT NOT NULL, 47 | city TEXT NOT NULL 48 | ); 49 | 50 | CREATE TABLE car_model 51 | ( 52 | car_model_id INT PRIMARY KEY GENERATED BY DEFAULT AS IDENTITY, 53 | make text, 54 | model text, 55 | UNIQUE (make, model) 56 | ); 57 | 58 | CREATE TABLE car ( 59 | car_id INT PRIMARY KEY GENERATED BY DEFAULT AS IDENTITY, 60 | number_of_owners INT NOT NULL, 61 | registration_number TEXT UNIQUE NOT NULL, 62 | manufacture_year INT NOT NULL, 63 | number_of_doors INT DEFAULT 5 NOT NULL, 64 | car_model_id INT NOT NULL REFERENCES car_model (car_model_id), 65 | mileage INT 66 | ); 67 | 68 | CREATE TABLE advertisement( 69 | advertisement_id INT PRIMARY KEY GENERATED BY DEFAULT AS IDENTITY, 70 | advertisement_date TIMESTAMP WITH TIME ZONE NOT NULL, 71 | car_id INT NOT NULL REFERENCES car(car_id), 72 | seller_account_id INT NOT NULL REFERENCES seller_account (seller_account_id) 73 | ); 74 | 75 | CREATE TABLE advertisement_picture( 76 | advertisement_picture_id INT PRIMARY KEY GENERATED BY DEFAULT AS IDENTITY, 77 | advertisement_id INT REFERENCES advertisement(advertisement_id), 78 | picture_location TEXT UNIQUE 79 | ); 80 | 81 | CREATE TABLE advertisement_rating ( 82 | advertisement_rating_id INT PRIMARY KEY GENERATED BY DEFAULT AS IDENTITY, 83 | advertisement_id INT NOT NULL REFERENCES advertisement(advertisement_id), 84 | account_id INT NOT NULL REFERENCES account(account_id), 85 | advertisement_rating_date DATE NOT NULL, 86 | rank INT NOT NULL, 87 | review TEXT NOT NULL, 88 | CHECK (char_length(review)<= 200), 89 | CHECK (rank IN (1,2,3,4,5)) 90 | ); 91 | 92 | CREATE TABLE favorite_advertisement( 93 | PRIMARY KEY (account_id,advertisement_id), 94 | account_id INT NOT NULL REFERENCES account(account_id), 95 | advertisement_id INT NOT NULL REFERENCES advertisement(advertisement_id) 96 | ); 97 | 98 | -------------------------------------------------------------------------------- /Chapter06/Advanced Query Writing/schema.sql: -------------------------------------------------------------------------------- 1 | -- This should be executed using psql. 2 | 3 | CREATE ROLE car_portal_app LOGIN; 4 | 5 | DROP DATABASE IF EXISTS car_portal; 6 | 7 | --For linux 8 | CREATE DATABASE car_portal ENCODING 'UTF-8' LC_COLLATE 'en_US.UTF-8' LC_CTYPE 'en_US.UTF-8' TEMPLATE template0 OWNER car_portal_app; 9 | 10 | -- For Windows: 11 | -- CREATE DATABASE car_portal ENCODING 'UTF-8' LC_COLLATE 'English_United States' LC_CTYPE 'English_United States' TEMPLATE template0 OWNER car_portal_app; 12 | 13 | \c car_portal 14 | 15 | CREATE SCHEMA car_portal_app AUTHORIZATION car_portal_app; 16 | 17 | SET search_path to car_portal_app; 18 | SET ROLE car_portal_app; 19 | 20 | CREATE TABLE account ( 21 | account_id INT PRIMARY KEY GENERATED BY DEFAULT AS IDENTITY, 22 | first_name TEXT NOT NULL, 23 | last_name TEXT NOT NULL, 24 | email TEXT NOT NULL UNIQUE, 25 | password TEXT NOT NULL, 26 | CHECK(first_name !~ '\s' AND last_name !~ '\s'), 27 | CHECK (email ~* '^\w+@\w+[.]\w+$'), 28 | CHECK (char_length(password)>=8) 29 | ); 30 | 31 | CREATE TABLE account_history ( 32 | account_history_id BIGINT PRIMARY KEY GENERATED BY DEFAULT AS IDENTITY, 33 | account_id INT NOT NULL REFERENCES account(account_id), 34 | search_key TEXT NOT NULL, 35 | search_date DATE NOT NULL, 36 | UNIQUE (account_id, search_key, search_date) 37 | ); 38 | 39 | CREATE TABLE seller_account ( 40 | seller_account_id INT PRIMARY KEY GENERATED BY DEFAULT AS IDENTITY, 41 | account_id INT NOT NULL REFERENCES account(account_id), 42 | total_rank FLOAT, 43 | number_of_advertisement INT, 44 | street_name TEXT NOT NULL, 45 | street_number TEXT NOT NULL, 46 | zip_code TEXT NOT NULL, 47 | city TEXT NOT NULL 48 | ); 49 | 50 | CREATE TABLE car_model 51 | ( 52 | car_model_id INT PRIMARY KEY GENERATED BY DEFAULT AS IDENTITY, 53 | make text, 54 | model text, 55 | UNIQUE (make, model) 56 | ); 57 | 58 | CREATE TABLE car ( 59 | car_id INT PRIMARY KEY GENERATED BY DEFAULT AS IDENTITY, 60 | number_of_owners INT NOT NULL, 61 | registration_number TEXT UNIQUE NOT NULL, 62 | manufacture_year INT NOT NULL, 63 | number_of_doors INT DEFAULT 5 NOT NULL, 64 | car_model_id INT NOT NULL REFERENCES car_model (car_model_id), 65 | mileage INT 66 | ); 67 | 68 | CREATE TABLE advertisement( 69 | advertisement_id INT PRIMARY KEY GENERATED BY DEFAULT AS IDENTITY, 70 | advertisement_date TIMESTAMP WITH TIME ZONE NOT NULL, 71 | car_id INT NOT NULL REFERENCES car(car_id), 72 | seller_account_id INT NOT NULL REFERENCES seller_account (seller_account_id) 73 | ); 74 | 75 | CREATE TABLE advertisement_picture( 76 | advertisement_picture_id INT PRIMARY KEY GENERATED BY DEFAULT AS IDENTITY, 77 | advertisement_id INT REFERENCES advertisement(advertisement_id), 78 | picture_location TEXT UNIQUE 79 | ); 80 | 81 | CREATE TABLE advertisement_rating ( 82 | advertisement_rating_id INT PRIMARY KEY GENERATED BY DEFAULT AS IDENTITY, 83 | advertisement_id INT NOT NULL REFERENCES advertisement(advertisement_id), 84 | account_id INT NOT NULL REFERENCES account(account_id), 85 | advertisement_rating_date DATE NOT NULL, 86 | rank INT NOT NULL, 87 | review TEXT NOT NULL, 88 | CHECK (char_length(review)<= 200), 89 | CHECK (rank IN (1,2,3,4,5)) 90 | ); 91 | 92 | CREATE TABLE favorite_advertisement( 93 | PRIMARY KEY (account_id,advertisement_id), 94 | account_id INT NOT NULL REFERENCES account(account_id), 95 | advertisement_id INT NOT NULL REFERENCES advertisement(advertisement_id) 96 | ); 97 | 98 | 99 | -------------------------------------------------------------------------------- /Chapter16/Scalability/streaming_replication/schema.sql: -------------------------------------------------------------------------------- 1 | -- This should be executed using psql. 2 | 3 | CREATE ROLE car_portal_app LOGIN; 4 | 5 | DROP DATABASE IF EXISTS car_portal; 6 | 7 | --For linux 8 | CREATE DATABASE car_portal ENCODING 'UTF-8' LC_COLLATE 'en_US.UTF-8' LC_CTYPE 'en_US.UTF-8' TEMPLATE template0 OWNER car_portal_app; 9 | 10 | -- For Windows: 11 | -- CREATE DATABASE car_portal ENCODING 'UTF-8' LC_COLLATE 'English_United States' LC_CTYPE 'English_United States' TEMPLATE template0 OWNER car_portal_app; 12 | 13 | \c car_portal 14 | 15 | CREATE SCHEMA car_portal_app AUTHORIZATION car_portal_app; 16 | 17 | SET search_path to car_portal_app; 18 | SET ROLE car_portal_app; 19 | 20 | CREATE TABLE account ( 21 | account_id INT PRIMARY KEY GENERATED BY DEFAULT AS IDENTITY, 22 | first_name TEXT NOT NULL, 23 | last_name TEXT NOT NULL, 24 | email TEXT NOT NULL UNIQUE, 25 | password TEXT NOT NULL, 26 | CHECK(first_name !~ '\s' AND last_name !~ '\s'), 27 | CHECK (email ~* '^\w+@\w+[.]\w+$'), 28 | CHECK (char_length(password)>=8) 29 | ); 30 | 31 | CREATE TABLE account_history ( 32 | account_history_id BIGINT PRIMARY KEY GENERATED BY DEFAULT AS IDENTITY, 33 | account_id INT NOT NULL REFERENCES account(account_id), 34 | search_key TEXT NOT NULL, 35 | search_date DATE NOT NULL, 36 | UNIQUE (account_id, search_key, search_date) 37 | ); 38 | 39 | CREATE TABLE seller_account ( 40 | seller_account_id INT PRIMARY KEY GENERATED BY DEFAULT AS IDENTITY, 41 | account_id INT NOT NULL REFERENCES account(account_id), 42 | total_rank FLOAT, 43 | number_of_advertisement INT, 44 | street_name TEXT NOT NULL, 45 | street_number TEXT NOT NULL, 46 | zip_code TEXT NOT NULL, 47 | city TEXT NOT NULL 48 | ); 49 | 50 | CREATE TABLE car_model 51 | ( 52 | car_model_id INT PRIMARY KEY GENERATED BY DEFAULT AS IDENTITY, 53 | make text, 54 | model text, 55 | UNIQUE (make, model) 56 | ); 57 | 58 | CREATE TABLE car ( 59 | car_id INT PRIMARY KEY GENERATED BY DEFAULT AS IDENTITY, 60 | number_of_owners INT NOT NULL, 61 | registration_number TEXT UNIQUE NOT NULL, 62 | manufacture_year INT NOT NULL, 63 | number_of_doors INT DEFAULT 5 NOT NULL, 64 | car_model_id INT NOT NULL REFERENCES car_model (car_model_id), 65 | mileage INT 66 | ); 67 | 68 | CREATE TABLE advertisement( 69 | advertisement_id INT PRIMARY KEY GENERATED BY DEFAULT AS IDENTITY, 70 | advertisement_date TIMESTAMP WITH TIME ZONE NOT NULL, 71 | car_id INT NOT NULL REFERENCES car(car_id), 72 | seller_account_id INT NOT NULL REFERENCES seller_account (seller_account_id) 73 | ); 74 | 75 | CREATE TABLE advertisement_picture( 76 | advertisement_picture_id INT PRIMARY KEY GENERATED BY DEFAULT AS IDENTITY, 77 | advertisement_id INT REFERENCES advertisement(advertisement_id), 78 | picture_location TEXT UNIQUE 79 | ); 80 | 81 | CREATE TABLE advertisement_rating ( 82 | advertisement_rating_id INT PRIMARY KEY GENERATED BY DEFAULT AS IDENTITY, 83 | advertisement_id INT NOT NULL REFERENCES advertisement(advertisement_id), 84 | account_id INT NOT NULL REFERENCES account(account_id), 85 | advertisement_rating_date DATE NOT NULL, 86 | rank INT NOT NULL, 87 | review TEXT NOT NULL, 88 | CHECK (char_length(review)<= 200), 89 | CHECK (rank IN (1,2,3,4,5)) 90 | ); 91 | 92 | CREATE TABLE favorite_advertisement( 93 | PRIMARY KEY (account_id,advertisement_id), 94 | account_id INT NOT NULL REFERENCES account(account_id), 95 | advertisement_id INT NOT NULL REFERENCES advertisement(advertisement_id) 96 | ); 97 | -------------------------------------------------------------------------------- /Chapter16/Scalability/logical_replication/schema.sql: -------------------------------------------------------------------------------- 1 | -- This should be executed using psql. 2 | 3 | CREATE ROLE car_portal_app LOGIN; 4 | 5 | DROP DATABASE IF EXISTS car_portal; 6 | 7 | --For linux 8 | CREATE DATABASE car_portal ENCODING 'UTF-8' LC_COLLATE 'en_US.UTF-8' LC_CTYPE 'en_US.UTF-8' TEMPLATE template0 OWNER car_portal_app; 9 | 10 | -- For Windows: 11 | -- CREATE DATABASE car_portal ENCODING 'UTF-8' LC_COLLATE 'English_United States' LC_CTYPE 'English_United States' TEMPLATE template0 OWNER car_portal_app; 12 | 13 | \c car_portal 14 | 15 | CREATE SCHEMA car_portal_app AUTHORIZATION car_portal_app; 16 | 17 | SET search_path to car_portal_app; 18 | SET ROLE car_portal_app; 19 | 20 | CREATE TABLE account ( 21 | account_id INT PRIMARY KEY GENERATED BY DEFAULT AS IDENTITY, 22 | first_name TEXT NOT NULL, 23 | last_name TEXT NOT NULL, 24 | email TEXT NOT NULL UNIQUE, 25 | password TEXT NOT NULL, 26 | CHECK(first_name !~ '\s' AND last_name !~ '\s'), 27 | CHECK (email ~* '^\w+@\w+[.]\w+$'), 28 | CHECK (char_length(password)>=8) 29 | ); 30 | 31 | CREATE TABLE account_history ( 32 | account_history_id BIGINT PRIMARY KEY GENERATED BY DEFAULT AS IDENTITY, 33 | account_id INT NOT NULL REFERENCES account(account_id), 34 | search_key TEXT NOT NULL, 35 | search_date DATE NOT NULL, 36 | UNIQUE (account_id, search_key, search_date) 37 | ); 38 | 39 | CREATE TABLE seller_account ( 40 | seller_account_id INT PRIMARY KEY GENERATED BY DEFAULT AS IDENTITY, 41 | account_id INT NOT NULL REFERENCES account(account_id), 42 | total_rank FLOAT, 43 | number_of_advertisement INT, 44 | street_name TEXT NOT NULL, 45 | street_number TEXT NOT NULL, 46 | zip_code TEXT NOT NULL, 47 | city TEXT NOT NULL 48 | ); 49 | 50 | CREATE TABLE car_model 51 | ( 52 | car_model_id INT PRIMARY KEY GENERATED BY DEFAULT AS IDENTITY, 53 | make text, 54 | model text, 55 | UNIQUE (make, model) 56 | ); 57 | 58 | CREATE TABLE car ( 59 | car_id INT PRIMARY KEY GENERATED BY DEFAULT AS IDENTITY, 60 | number_of_owners INT NOT NULL, 61 | registration_number TEXT UNIQUE NOT NULL, 62 | manufacture_year INT NOT NULL, 63 | number_of_doors INT DEFAULT 5 NOT NULL, 64 | car_model_id INT NOT NULL REFERENCES car_model (car_model_id), 65 | mileage INT 66 | ); 67 | 68 | CREATE TABLE advertisement( 69 | advertisement_id INT PRIMARY KEY GENERATED BY DEFAULT AS IDENTITY, 70 | advertisement_date TIMESTAMP WITH TIME ZONE NOT NULL, 71 | car_id INT NOT NULL REFERENCES car(car_id), 72 | seller_account_id INT NOT NULL REFERENCES seller_account (seller_account_id) 73 | ); 74 | 75 | CREATE TABLE advertisement_picture( 76 | advertisement_picture_id INT PRIMARY KEY GENERATED BY DEFAULT AS IDENTITY, 77 | advertisement_id INT REFERENCES advertisement(advertisement_id), 78 | picture_location TEXT UNIQUE 79 | ); 80 | 81 | CREATE TABLE advertisement_rating ( 82 | advertisement_rating_id INT PRIMARY KEY GENERATED BY DEFAULT AS IDENTITY, 83 | advertisement_id INT NOT NULL REFERENCES advertisement(advertisement_id), 84 | account_id INT NOT NULL REFERENCES account(account_id), 85 | advertisement_rating_date DATE NOT NULL, 86 | rank INT NOT NULL, 87 | review TEXT NOT NULL, 88 | CHECK (char_length(review)<= 200), 89 | CHECK (rank IN (1,2,3,4,5)) 90 | ); 91 | 92 | CREATE TABLE favorite_advertisement( 93 | PRIMARY KEY (account_id,advertisement_id), 94 | account_id INT NOT NULL REFERENCES account(account_id), 95 | advertisement_id INT NOT NULL REFERENCES advertisement(advertisement_id) 96 | ); 97 | 98 | -------------------------------------------------------------------------------- /Chapter15/Using PostgreSQL in Python applications/schema.sql: -------------------------------------------------------------------------------- 1 | -- This should be executed using psql. 2 | 3 | CREATE ROLE car_portal_app LOGIN; 4 | 5 | DROP DATABASE IF EXISTS car_portal; 6 | 7 | --For linux 8 | CREATE DATABASE car_portal ENCODING 'UTF-8' LC_COLLATE 'en_US.UTF-8' LC_CTYPE 'en_US.UTF-8' TEMPLATE template0 OWNER car_portal_app; 9 | 10 | -- For Windows: 11 | -- CREATE DATABASE car_portal ENCODING 'UTF-8' LC_COLLATE 'English_United States' LC_CTYPE 'English_United States' TEMPLATE template0 OWNER car_portal_app; 12 | 13 | \c car_portal 14 | 15 | CREATE SCHEMA car_portal_app AUTHORIZATION car_portal_app; 16 | 17 | SET search_path to car_portal_app; 18 | SET ROLE car_portal_app; 19 | 20 | CREATE TABLE account ( 21 | account_id INT PRIMARY KEY GENERATED BY DEFAULT AS IDENTITY, 22 | first_name TEXT NOT NULL, 23 | last_name TEXT NOT NULL, 24 | email TEXT NOT NULL UNIQUE, 25 | password TEXT NOT NULL, 26 | CHECK(first_name !~ '\s' AND last_name !~ '\s'), 27 | CHECK (email ~* '^\w+@\w+[.]\w+$'), 28 | CHECK (char_length(password)>=8) 29 | ); 30 | 31 | CREATE TABLE account_history ( 32 | account_history_id BIGINT PRIMARY KEY GENERATED BY DEFAULT AS IDENTITY, 33 | account_id INT NOT NULL REFERENCES account(account_id), 34 | search_key TEXT NOT NULL, 35 | search_date DATE NOT NULL, 36 | UNIQUE (account_id, search_key, search_date) 37 | ); 38 | 39 | CREATE TABLE seller_account ( 40 | seller_account_id INT PRIMARY KEY GENERATED BY DEFAULT AS IDENTITY, 41 | account_id INT NOT NULL REFERENCES account(account_id), 42 | total_rank FLOAT, 43 | number_of_advertisement INT, 44 | street_name TEXT NOT NULL, 45 | street_number TEXT NOT NULL, 46 | zip_code TEXT NOT NULL, 47 | city TEXT NOT NULL 48 | ); 49 | 50 | CREATE TABLE car_model 51 | ( 52 | car_model_id INT PRIMARY KEY GENERATED BY DEFAULT AS IDENTITY, 53 | make text, 54 | model text, 55 | UNIQUE (make, model) 56 | ); 57 | 58 | CREATE TABLE car ( 59 | car_id INT PRIMARY KEY GENERATED BY DEFAULT AS IDENTITY, 60 | number_of_owners INT NOT NULL, 61 | registration_number TEXT UNIQUE NOT NULL, 62 | manufacture_year INT NOT NULL, 63 | number_of_doors INT DEFAULT 5 NOT NULL, 64 | car_model_id INT NOT NULL REFERENCES car_model (car_model_id), 65 | mileage INT 66 | ); 67 | 68 | CREATE TABLE advertisement( 69 | advertisement_id INT PRIMARY KEY GENERATED BY DEFAULT AS IDENTITY, 70 | advertisement_date TIMESTAMP WITH TIME ZONE NOT NULL, 71 | car_id INT NOT NULL REFERENCES car(car_id), 72 | seller_account_id INT NOT NULL REFERENCES seller_account (seller_account_id) 73 | ); 74 | 75 | CREATE TABLE advertisement_picture( 76 | advertisement_picture_id INT PRIMARY KEY GENERATED BY DEFAULT AS IDENTITY, 77 | advertisement_id INT REFERENCES advertisement(advertisement_id), 78 | picture_location TEXT UNIQUE 79 | ); 80 | 81 | CREATE TABLE advertisement_rating ( 82 | advertisement_rating_id INT PRIMARY KEY GENERATED BY DEFAULT AS IDENTITY, 83 | advertisement_id INT NOT NULL REFERENCES advertisement(advertisement_id), 84 | account_id INT NOT NULL REFERENCES account(account_id), 85 | advertisement_rating_date DATE NOT NULL, 86 | rank INT NOT NULL, 87 | review TEXT NOT NULL, 88 | CHECK (char_length(review)<= 200), 89 | CHECK (rank IN (1,2,3,4,5)) 90 | ); 91 | 92 | CREATE TABLE favorite_advertisement( 93 | PRIMARY KEY (account_id,advertisement_id), 94 | account_id INT NOT NULL REFERENCES account(account_id), 95 | advertisement_id INT NOT NULL REFERENCES advertisement(advertisement_id) 96 | ); 97 | 98 | -------------------------------------------------------------------------------- /Chapter08/OLAP and data warehousing/schema.sql: -------------------------------------------------------------------------------- 1 | -- This should be executed using psql. 2 | 3 | CREATE ROLE car_portal_app LOGIN; 4 | 5 | DROP DATABASE IF EXISTS car_portal; 6 | 7 | --For linux 8 | CREATE DATABASE car_portal ENCODING 'UTF-8' LC_COLLATE 'en_US.UTF-8' LC_CTYPE 'en_US.UTF-8' TEMPLATE template0 OWNER car_portal_app; 9 | 10 | -- For Windows: 11 | -- CREATE DATABASE car_portal ENCODING 'UTF-8' LC_COLLATE 'English_United States' LC_CTYPE 'English_United States' TEMPLATE template0 OWNER car_portal_app; 12 | 13 | \c car_portal 14 | 15 | CREATE SCHEMA car_portal_app AUTHORIZATION car_portal_app; 16 | 17 | SET search_path to car_portal_app; 18 | SET ROLE car_portal_app; 19 | 20 | CREATE TABLE account ( 21 | account_id INT PRIMARY KEY GENERATED BY DEFAULT AS IDENTITY, 22 | first_name TEXT NOT NULL, 23 | last_name TEXT NOT NULL, 24 | email TEXT NOT NULL UNIQUE, 25 | password TEXT NOT NULL, 26 | CHECK(first_name !~ '\s' AND last_name !~ '\s'), 27 | CHECK (email ~* '^\w+@\w+[.]\w+$'), 28 | CHECK (char_length(password)>=8) 29 | ); 30 | 31 | CREATE TABLE account_history ( 32 | account_history_id BIGINT PRIMARY KEY GENERATED BY DEFAULT AS IDENTITY, 33 | account_id INT NOT NULL REFERENCES account(account_id), 34 | search_key TEXT NOT NULL, 35 | search_date DATE NOT NULL, 36 | UNIQUE (account_id, search_key, search_date) 37 | ); 38 | 39 | CREATE TABLE seller_account ( 40 | seller_account_id INT PRIMARY KEY GENERATED BY DEFAULT AS IDENTITY, 41 | account_id INT NOT NULL REFERENCES account(account_id), 42 | total_rank FLOAT, 43 | number_of_advertisement INT, 44 | street_name TEXT NOT NULL, 45 | street_number TEXT NOT NULL, 46 | zip_code TEXT NOT NULL, 47 | city TEXT NOT NULL 48 | ); 49 | 50 | CREATE TABLE car_model 51 | ( 52 | car_model_id INT PRIMARY KEY GENERATED BY DEFAULT AS IDENTITY, 53 | make text, 54 | model text, 55 | UNIQUE (make, model) 56 | ); 57 | 58 | CREATE TABLE car ( 59 | car_id INT PRIMARY KEY GENERATED BY DEFAULT AS IDENTITY, 60 | number_of_owners INT NOT NULL, 61 | registration_number TEXT UNIQUE NOT NULL, 62 | manufacture_year INT NOT NULL, 63 | number_of_doors INT DEFAULT 5 NOT NULL, 64 | car_model_id INT NOT NULL REFERENCES car_model (car_model_id), 65 | mileage INT 66 | ); 67 | 68 | CREATE TABLE advertisement( 69 | advertisement_id INT PRIMARY KEY GENERATED BY DEFAULT AS IDENTITY, 70 | advertisement_date TIMESTAMP WITH TIME ZONE NOT NULL, 71 | car_id INT NOT NULL REFERENCES car(car_id), 72 | seller_account_id INT NOT NULL REFERENCES seller_account (seller_account_id) 73 | ); 74 | 75 | CREATE TABLE advertisement_picture( 76 | advertisement_picture_id INT PRIMARY KEY GENERATED BY DEFAULT AS IDENTITY, 77 | advertisement_id INT REFERENCES advertisement(advertisement_id), 78 | picture_location TEXT UNIQUE 79 | ); 80 | 81 | CREATE TABLE advertisement_rating ( 82 | advertisement_rating_id INT PRIMARY KEY GENERATED BY DEFAULT AS IDENTITY, 83 | advertisement_id INT NOT NULL REFERENCES advertisement(advertisement_id), 84 | account_id INT NOT NULL REFERENCES account(account_id), 85 | advertisement_rating_date DATE NOT NULL, 86 | rank INT NOT NULL, 87 | review TEXT NOT NULL, 88 | CHECK (char_length(review)<= 200), 89 | CHECK (rank IN (1,2,3,4,5)) 90 | ); 91 | 92 | CREATE TABLE favorite_advertisement( 93 | PRIMARY KEY (account_id,advertisement_id), 94 | account_id INT NOT NULL REFERENCES account(account_id), 95 | advertisement_id INT NOT NULL REFERENCES advertisement(advertisement_id) 96 | ); 97 | 98 | 99 | CREATE SCHEMA dwh AUTHORIZATION car_portal_app; 100 | 101 | SET search_path to dwh; 102 | 103 | -------------------------------------------------------------------------------- /Chapter03/car_portal/schema.sql: -------------------------------------------------------------------------------- 1 | -- This should be executed using psql. 2 | 3 | CREATE ROLE car_portal_app LOGIN; 4 | 5 | DROP DATABASE IF EXISTS car_portal; 6 | 7 | --For linux 8 | CREATE DATABASE car_portal ENCODING 'UTF-8' LC_COLLATE 'en_US.UTF-8' LC_CTYPE 'en_US.UTF-8' TEMPLATE template0 OWNER car_portal_app; 9 | 10 | -- For Windows: 11 | -- CREATE DATABASE car_portal ENCODING 'UTF-8' LC_COLLATE 'English_United States' LC_CTYPE 'English_United States' TEMPLATE template0 OWNER car_portal_app; 12 | 13 | \c car_portal 14 | 15 | CREATE SCHEMA car_portal_app AUTHORIZATION car_portal_app; 16 | 17 | SET search_path to car_portal_app; 18 | SET ROLE car_portal_app; 19 | 20 | CREATE TABLE account ( 21 | account_id INT PRIMARY KEY GENERATED BY DEFAULT AS IDENTITY, 22 | first_name TEXT NOT NULL, 23 | last_name TEXT NOT NULL, 24 | email TEXT NOT NULL UNIQUE, 25 | password TEXT NOT NULL, 26 | CHECK(first_name !~ '\s' AND last_name !~ '\s'), 27 | CHECK (email ~* '^\w+@\w+[.]\w+$'), 28 | CHECK (char_length(password)>=8) 29 | ); 30 | 31 | CREATE TABLE account_history ( 32 | account_history_id BIGINT PRIMARY KEY GENERATED BY DEFAULT AS IDENTITY, 33 | account_id INT NOT NULL REFERENCES account(account_id), 34 | search_key TEXT NOT NULL, 35 | search_date DATE NOT NULL, 36 | UNIQUE (account_id, search_key, search_date) 37 | ); 38 | 39 | CREATE TABLE seller_account ( 40 | seller_account_id INT PRIMARY KEY GENERATED BY DEFAULT AS IDENTITY, 41 | account_id INT NOT NULL REFERENCES account(account_id), 42 | total_rank FLOAT, 43 | number_of_advertisement INT, 44 | street_name TEXT NOT NULL, 45 | street_number TEXT NOT NULL, 46 | zip_code TEXT NOT NULL, 47 | city TEXT NOT NULL 48 | ); 49 | 50 | CREATE TABLE car_model 51 | ( 52 | car_model_id INT PRIMARY KEY GENERATED BY DEFAULT AS IDENTITY, 53 | make text, 54 | model text, 55 | UNIQUE (make, model) 56 | ); 57 | 58 | CREATE TABLE car ( 59 | car_id INT PRIMARY KEY GENERATED BY DEFAULT AS IDENTITY, 60 | number_of_owners INT NOT NULL, 61 | registration_number TEXT UNIQUE NOT NULL, 62 | manufacture_year INT NOT NULL, 63 | number_of_doors INT DEFAULT 5 NOT NULL, 64 | car_model_id INT NOT NULL REFERENCES car_model (car_model_id), 65 | mileage INT 66 | ); 67 | 68 | CREATE TABLE advertisement( 69 | advertisement_id INT PRIMARY KEY GENERATED BY DEFAULT AS IDENTITY, 70 | advertisement_date TIMESTAMP WITH TIME ZONE NOT NULL, 71 | car_id INT NOT NULL REFERENCES car(car_id), 72 | seller_account_id INT NOT NULL REFERENCES seller_account (seller_account_id) 73 | ); 74 | 75 | CREATE TABLE advertisement_picture( 76 | advertisement_picture_id INT PRIMARY KEY GENERATED BY DEFAULT AS IDENTITY, 77 | advertisement_id INT REFERENCES advertisement(advertisement_id), 78 | picture_location TEXT UNIQUE 79 | ); 80 | 81 | CREATE TABLE advertisement_rating ( 82 | advertisement_rating_id INT PRIMARY KEY GENERATED BY DEFAULT AS IDENTITY, 83 | advertisement_id INT NOT NULL REFERENCES advertisement(advertisement_id), 84 | account_id INT NOT NULL REFERENCES account(account_id), 85 | advertisement_rating_date DATE NOT NULL, 86 | rank INT NOT NULL, 87 | review TEXT NOT NULL, 88 | CHECK (char_length(review)<= 200), 89 | CHECK (rank IN (1,2,3,4,5)) 90 | ); 91 | 92 | CREATE TABLE favorite_advertisement( 93 | PRIMARY KEY (account_id,advertisement_id), 94 | account_id INT NOT NULL REFERENCES account(account_id), 95 | advertisement_id INT NOT NULL REFERENCES advertisement(advertisement_id) 96 | ); 97 | 98 | 99 | -- The sample table for the chapter SQL Language 100 | CREATE TABLE a 101 | ( 102 | a_int INT, 103 | a_text TEXT 104 | ); 105 | 106 | CREATE TABLE b 107 | ( 108 | b_int INT UNIQUE, 109 | b_text TEXT 110 | ); 111 | -------------------------------------------------------------------------------- /Chapter04/car_portal/schema.sql: -------------------------------------------------------------------------------- 1 | -- This should be executed using psql. 2 | 3 | CREATE ROLE car_portal_app LOGIN; 4 | 5 | DROP DATABASE IF EXISTS car_portal; 6 | 7 | --For linux 8 | CREATE DATABASE car_portal ENCODING 'UTF-8' LC_COLLATE 'en_US.UTF-8' LC_CTYPE 'en_US.UTF-8' TEMPLATE template0 OWNER car_portal_app; 9 | 10 | -- For Windows: 11 | -- CREATE DATABASE car_portal ENCODING 'UTF-8' LC_COLLATE 'English_United States' LC_CTYPE 'English_United States' TEMPLATE template0 OWNER car_portal_app; 12 | 13 | \c car_portal 14 | 15 | CREATE SCHEMA car_portal_app AUTHORIZATION car_portal_app; 16 | 17 | SET search_path to car_portal_app; 18 | SET ROLE car_portal_app; 19 | 20 | CREATE TABLE account ( 21 | account_id INT PRIMARY KEY GENERATED BY DEFAULT AS IDENTITY, 22 | first_name TEXT NOT NULL, 23 | last_name TEXT NOT NULL, 24 | email TEXT NOT NULL UNIQUE, 25 | password TEXT NOT NULL, 26 | CHECK(first_name !~ '\s' AND last_name !~ '\s'), 27 | CHECK (email ~* '^\w+@\w+[.]\w+$'), 28 | CHECK (char_length(password)>=8) 29 | ); 30 | 31 | CREATE TABLE account_history ( 32 | account_history_id BIGINT PRIMARY KEY GENERATED BY DEFAULT AS IDENTITY, 33 | account_id INT NOT NULL REFERENCES account(account_id), 34 | search_key TEXT NOT NULL, 35 | search_date DATE NOT NULL, 36 | UNIQUE (account_id, search_key, search_date) 37 | ); 38 | 39 | CREATE TABLE seller_account ( 40 | seller_account_id INT PRIMARY KEY GENERATED BY DEFAULT AS IDENTITY, 41 | account_id INT NOT NULL REFERENCES account(account_id), 42 | total_rank FLOAT, 43 | number_of_advertisement INT, 44 | street_name TEXT NOT NULL, 45 | street_number TEXT NOT NULL, 46 | zip_code TEXT NOT NULL, 47 | city TEXT NOT NULL 48 | ); 49 | 50 | CREATE TABLE car_model 51 | ( 52 | car_model_id INT PRIMARY KEY GENERATED BY DEFAULT AS IDENTITY, 53 | make text, 54 | model text, 55 | UNIQUE (make, model) 56 | ); 57 | 58 | CREATE TABLE car ( 59 | car_id INT PRIMARY KEY GENERATED BY DEFAULT AS IDENTITY, 60 | number_of_owners INT NOT NULL, 61 | registration_number TEXT UNIQUE NOT NULL, 62 | manufacture_year INT NOT NULL, 63 | number_of_doors INT DEFAULT 5 NOT NULL, 64 | car_model_id INT NOT NULL REFERENCES car_model (car_model_id), 65 | mileage INT 66 | ); 67 | 68 | CREATE TABLE advertisement( 69 | advertisement_id INT PRIMARY KEY GENERATED BY DEFAULT AS IDENTITY, 70 | advertisement_date TIMESTAMP WITH TIME ZONE NOT NULL, 71 | car_id INT NOT NULL REFERENCES car(car_id), 72 | seller_account_id INT NOT NULL REFERENCES seller_account (seller_account_id) 73 | ); 74 | 75 | CREATE TABLE advertisement_picture( 76 | advertisement_picture_id INT PRIMARY KEY GENERATED BY DEFAULT AS IDENTITY, 77 | advertisement_id INT REFERENCES advertisement(advertisement_id), 78 | picture_location TEXT UNIQUE 79 | ); 80 | 81 | CREATE TABLE advertisement_rating ( 82 | advertisement_rating_id INT PRIMARY KEY GENERATED BY DEFAULT AS IDENTITY, 83 | advertisement_id INT NOT NULL REFERENCES advertisement(advertisement_id), 84 | account_id INT NOT NULL REFERENCES account(account_id), 85 | advertisement_rating_date DATE NOT NULL, 86 | rank INT NOT NULL, 87 | review TEXT NOT NULL, 88 | CHECK (char_length(review)<= 200), 89 | CHECK (rank IN (1,2,3,4,5)) 90 | ); 91 | 92 | CREATE TABLE favorite_advertisement( 93 | PRIMARY KEY (account_id,advertisement_id), 94 | account_id INT NOT NULL REFERENCES account(account_id), 95 | advertisement_id INT NOT NULL REFERENCES advertisement(advertisement_id) 96 | ); 97 | 98 | 99 | -- The sample table for the chapter SQL Language 100 | CREATE TABLE a 101 | ( 102 | a_int INT, 103 | a_text TEXT 104 | ); 105 | 106 | CREATE TABLE b 107 | ( 108 | b_int INT UNIQUE, 109 | b_text TEXT 110 | ); 111 | -------------------------------------------------------------------------------- /Chapter05/SQL Language/schema.sql: -------------------------------------------------------------------------------- 1 | -- This should be executed using psql. 2 | 3 | CREATE ROLE car_portal_app LOGIN; 4 | 5 | DROP DATABASE IF EXISTS car_portal; 6 | 7 | --For linux 8 | CREATE DATABASE car_portal ENCODING 'UTF-8' LC_COLLATE 'en_US.UTF-8' LC_CTYPE 'en_US.UTF-8' TEMPLATE template0 OWNER car_portal_app; 9 | 10 | -- For Windows: 11 | -- CREATE DATABASE car_portal ENCODING 'UTF-8' LC_COLLATE 'English_United States' LC_CTYPE 'English_United States' TEMPLATE template0 OWNER car_portal_app; 12 | 13 | \c car_portal 14 | 15 | CREATE SCHEMA car_portal_app AUTHORIZATION car_portal_app; 16 | 17 | SET search_path to car_portal_app; 18 | SET ROLE car_portal_app; 19 | 20 | CREATE TABLE account ( 21 | account_id INT PRIMARY KEY GENERATED BY DEFAULT AS IDENTITY, 22 | first_name TEXT NOT NULL, 23 | last_name TEXT NOT NULL, 24 | email TEXT NOT NULL UNIQUE, 25 | password TEXT NOT NULL, 26 | CHECK(first_name !~ '\s' AND last_name !~ '\s'), 27 | CHECK (email ~* '^\w+@\w+[.]\w+$'), 28 | CHECK (char_length(password)>=8) 29 | ); 30 | 31 | CREATE TABLE account_history ( 32 | account_history_id BIGINT PRIMARY KEY GENERATED BY DEFAULT AS IDENTITY, 33 | account_id INT NOT NULL REFERENCES account(account_id), 34 | search_key TEXT NOT NULL, 35 | search_date DATE NOT NULL, 36 | UNIQUE (account_id, search_key, search_date) 37 | ); 38 | 39 | CREATE TABLE seller_account ( 40 | seller_account_id INT PRIMARY KEY GENERATED BY DEFAULT AS IDENTITY, 41 | account_id INT NOT NULL REFERENCES account(account_id), 42 | total_rank FLOAT, 43 | number_of_advertisement INT, 44 | street_name TEXT NOT NULL, 45 | street_number TEXT NOT NULL, 46 | zip_code TEXT NOT NULL, 47 | city TEXT NOT NULL 48 | ); 49 | 50 | CREATE TABLE car_model 51 | ( 52 | car_model_id INT PRIMARY KEY GENERATED BY DEFAULT AS IDENTITY, 53 | make text, 54 | model text, 55 | UNIQUE (make, model) 56 | ); 57 | 58 | CREATE TABLE car ( 59 | car_id INT PRIMARY KEY GENERATED BY DEFAULT AS IDENTITY, 60 | number_of_owners INT NOT NULL, 61 | registration_number TEXT UNIQUE NOT NULL, 62 | manufacture_year INT NOT NULL, 63 | number_of_doors INT DEFAULT 5 NOT NULL, 64 | car_model_id INT NOT NULL REFERENCES car_model (car_model_id), 65 | mileage INT 66 | ); 67 | 68 | CREATE TABLE advertisement( 69 | advertisement_id INT PRIMARY KEY GENERATED BY DEFAULT AS IDENTITY, 70 | advertisement_date TIMESTAMP WITH TIME ZONE NOT NULL, 71 | car_id INT NOT NULL REFERENCES car(car_id), 72 | seller_account_id INT NOT NULL REFERENCES seller_account (seller_account_id) 73 | ); 74 | 75 | CREATE TABLE advertisement_picture( 76 | advertisement_picture_id INT PRIMARY KEY GENERATED BY DEFAULT AS IDENTITY, 77 | advertisement_id INT REFERENCES advertisement(advertisement_id), 78 | picture_location TEXT UNIQUE 79 | ); 80 | 81 | CREATE TABLE advertisement_rating ( 82 | advertisement_rating_id INT PRIMARY KEY GENERATED BY DEFAULT AS IDENTITY, 83 | advertisement_id INT NOT NULL REFERENCES advertisement(advertisement_id), 84 | account_id INT NOT NULL REFERENCES account(account_id), 85 | advertisement_rating_date DATE NOT NULL, 86 | rank INT NOT NULL, 87 | review TEXT NOT NULL, 88 | CHECK (char_length(review)<= 200), 89 | CHECK (rank IN (1,2,3,4,5)) 90 | ); 91 | 92 | CREATE TABLE favorite_advertisement( 93 | PRIMARY KEY (account_id,advertisement_id), 94 | account_id INT NOT NULL REFERENCES account(account_id), 95 | advertisement_id INT NOT NULL REFERENCES advertisement(advertisement_id) 96 | ); 97 | 98 | 99 | -- The sample table for the chapter SQL Language 100 | CREATE TABLE a 101 | ( 102 | a_int INT, 103 | a_text TEXT 104 | ); 105 | 106 | CREATE TABLE b 107 | ( 108 | b_int INT UNIQUE, 109 | b_text TEXT 110 | ); 111 | -------------------------------------------------------------------------------- /Chapter07/car_portal/schema.sql: -------------------------------------------------------------------------------- 1 | -- This should be executed using psql. 2 | 3 | CREATE ROLE car_portal_app LOGIN; 4 | 5 | DROP DATABASE IF EXISTS car_portal; 6 | 7 | --For linux 8 | CREATE DATABASE car_portal ENCODING 'UTF-8' LC_COLLATE 'en_US.UTF-8' LC_CTYPE 'en_US.UTF-8' TEMPLATE template0 OWNER car_portal_app; 9 | 10 | -- For Windows: 11 | -- CREATE DATABASE car_portal ENCODING 'UTF-8' LC_COLLATE 'English_United States' LC_CTYPE 'English_United States' TEMPLATE template0 OWNER car_portal_app; 12 | 13 | \c car_portal 14 | 15 | CREATE SCHEMA car_portal_app AUTHORIZATION car_portal_app; 16 | 17 | SET search_path to car_portal_app; 18 | SET ROLE car_portal_app; 19 | 20 | CREATE TABLE account ( 21 | account_id INT PRIMARY KEY GENERATED BY DEFAULT AS IDENTITY, 22 | first_name TEXT NOT NULL, 23 | last_name TEXT NOT NULL, 24 | email TEXT NOT NULL UNIQUE, 25 | password TEXT NOT NULL, 26 | CHECK(first_name !~ '\s' AND last_name !~ '\s'), 27 | CHECK (email ~* '^\w+@\w+[.]\w+$'), 28 | CHECK (char_length(password)>=8) 29 | ); 30 | 31 | CREATE TABLE account_history ( 32 | account_history_id BIGINT PRIMARY KEY GENERATED BY DEFAULT AS IDENTITY, 33 | account_id INT NOT NULL REFERENCES account(account_id), 34 | search_key TEXT NOT NULL, 35 | search_date DATE NOT NULL, 36 | UNIQUE (account_id, search_key, search_date) 37 | ); 38 | 39 | CREATE TABLE seller_account ( 40 | seller_account_id INT PRIMARY KEY GENERATED BY DEFAULT AS IDENTITY, 41 | account_id INT NOT NULL REFERENCES account(account_id), 42 | total_rank FLOAT, 43 | number_of_advertisement INT, 44 | street_name TEXT NOT NULL, 45 | street_number TEXT NOT NULL, 46 | zip_code TEXT NOT NULL, 47 | city TEXT NOT NULL 48 | ); 49 | 50 | CREATE TABLE car_model 51 | ( 52 | car_model_id INT PRIMARY KEY GENERATED BY DEFAULT AS IDENTITY, 53 | make text, 54 | model text, 55 | UNIQUE (make, model) 56 | ); 57 | 58 | CREATE TABLE car ( 59 | car_id INT PRIMARY KEY GENERATED BY DEFAULT AS IDENTITY, 60 | number_of_owners INT NOT NULL, 61 | registration_number TEXT UNIQUE NOT NULL, 62 | manufacture_year INT NOT NULL, 63 | number_of_doors INT DEFAULT 5 NOT NULL, 64 | car_model_id INT NOT NULL REFERENCES car_model (car_model_id), 65 | mileage INT 66 | ); 67 | 68 | CREATE TABLE advertisement( 69 | advertisement_id INT PRIMARY KEY GENERATED BY DEFAULT AS IDENTITY, 70 | advertisement_date TIMESTAMP WITH TIME ZONE NOT NULL, 71 | car_id INT NOT NULL REFERENCES car(car_id), 72 | seller_account_id INT NOT NULL REFERENCES seller_account (seller_account_id) 73 | ); 74 | 75 | CREATE TABLE advertisement_picture( 76 | advertisement_picture_id INT PRIMARY KEY GENERATED BY DEFAULT AS IDENTITY, 77 | advertisement_id INT REFERENCES advertisement(advertisement_id), 78 | picture_location TEXT UNIQUE 79 | ); 80 | 81 | CREATE TABLE advertisement_rating ( 82 | advertisement_rating_id INT PRIMARY KEY GENERATED BY DEFAULT AS IDENTITY, 83 | advertisement_id INT NOT NULL REFERENCES advertisement(advertisement_id), 84 | account_id INT NOT NULL REFERENCES account(account_id), 85 | advertisement_rating_date DATE NOT NULL, 86 | rank INT NOT NULL, 87 | review TEXT NOT NULL, 88 | CHECK (char_length(review)<= 200), 89 | CHECK (rank IN (1,2,3,4,5)) 90 | ); 91 | 92 | CREATE TABLE favorite_advertisement( 93 | PRIMARY KEY (account_id,advertisement_id), 94 | account_id INT NOT NULL REFERENCES account(account_id), 95 | advertisement_id INT NOT NULL REFERENCES advertisement(advertisement_id) 96 | ); 97 | 98 | 99 | -- The sample table for the chapter SQL Language 100 | CREATE TABLE a 101 | ( 102 | a_int INT, 103 | a_text TEXT 104 | ); 105 | 106 | CREATE TABLE b 107 | ( 108 | b_int INT UNIQUE, 109 | b_text TEXT 110 | ); 111 | -------------------------------------------------------------------------------- /Chapter11/car_portal/schema.sql: -------------------------------------------------------------------------------- 1 | -- This should be executed using psql. 2 | 3 | CREATE ROLE car_portal_app LOGIN; 4 | 5 | DROP DATABASE IF EXISTS car_portal; 6 | 7 | --For linux 8 | CREATE DATABASE car_portal ENCODING 'UTF-8' LC_COLLATE 'en_US.UTF-8' LC_CTYPE 'en_US.UTF-8' TEMPLATE template0 OWNER car_portal_app; 9 | 10 | -- For Windows: 11 | -- CREATE DATABASE car_portal ENCODING 'UTF-8' LC_COLLATE 'English_United States' LC_CTYPE 'English_United States' TEMPLATE template0 OWNER car_portal_app; 12 | 13 | \c car_portal 14 | 15 | CREATE SCHEMA car_portal_app AUTHORIZATION car_portal_app; 16 | 17 | SET search_path to car_portal_app; 18 | SET ROLE car_portal_app; 19 | 20 | CREATE TABLE account ( 21 | account_id INT PRIMARY KEY GENERATED BY DEFAULT AS IDENTITY, 22 | first_name TEXT NOT NULL, 23 | last_name TEXT NOT NULL, 24 | email TEXT NOT NULL UNIQUE, 25 | password TEXT NOT NULL, 26 | CHECK(first_name !~ '\s' AND last_name !~ '\s'), 27 | CHECK (email ~* '^\w+@\w+[.]\w+$'), 28 | CHECK (char_length(password)>=8) 29 | ); 30 | 31 | CREATE TABLE account_history ( 32 | account_history_id BIGINT PRIMARY KEY GENERATED BY DEFAULT AS IDENTITY, 33 | account_id INT NOT NULL REFERENCES account(account_id), 34 | search_key TEXT NOT NULL, 35 | search_date DATE NOT NULL, 36 | UNIQUE (account_id, search_key, search_date) 37 | ); 38 | 39 | CREATE TABLE seller_account ( 40 | seller_account_id INT PRIMARY KEY GENERATED BY DEFAULT AS IDENTITY, 41 | account_id INT NOT NULL REFERENCES account(account_id), 42 | total_rank FLOAT, 43 | number_of_advertisement INT, 44 | street_name TEXT NOT NULL, 45 | street_number TEXT NOT NULL, 46 | zip_code TEXT NOT NULL, 47 | city TEXT NOT NULL 48 | ); 49 | 50 | CREATE TABLE car_model 51 | ( 52 | car_model_id INT PRIMARY KEY GENERATED BY DEFAULT AS IDENTITY, 53 | make text, 54 | model text, 55 | UNIQUE (make, model) 56 | ); 57 | 58 | CREATE TABLE car ( 59 | car_id INT PRIMARY KEY GENERATED BY DEFAULT AS IDENTITY, 60 | number_of_owners INT NOT NULL, 61 | registration_number TEXT UNIQUE NOT NULL, 62 | manufacture_year INT NOT NULL, 63 | number_of_doors INT DEFAULT 5 NOT NULL, 64 | car_model_id INT NOT NULL REFERENCES car_model (car_model_id), 65 | mileage INT 66 | ); 67 | 68 | CREATE TABLE advertisement( 69 | advertisement_id INT PRIMARY KEY GENERATED BY DEFAULT AS IDENTITY, 70 | advertisement_date TIMESTAMP WITH TIME ZONE NOT NULL, 71 | car_id INT NOT NULL REFERENCES car(car_id), 72 | seller_account_id INT NOT NULL REFERENCES seller_account (seller_account_id) 73 | ); 74 | 75 | CREATE TABLE advertisement_picture( 76 | advertisement_picture_id INT PRIMARY KEY GENERATED BY DEFAULT AS IDENTITY, 77 | advertisement_id INT REFERENCES advertisement(advertisement_id), 78 | picture_location TEXT UNIQUE 79 | ); 80 | 81 | CREATE TABLE advertisement_rating ( 82 | advertisement_rating_id INT PRIMARY KEY GENERATED BY DEFAULT AS IDENTITY, 83 | advertisement_id INT NOT NULL REFERENCES advertisement(advertisement_id), 84 | account_id INT NOT NULL REFERENCES account(account_id), 85 | advertisement_rating_date DATE NOT NULL, 86 | rank INT NOT NULL, 87 | review TEXT NOT NULL, 88 | CHECK (char_length(review)<= 200), 89 | CHECK (rank IN (1,2,3,4,5)) 90 | ); 91 | 92 | CREATE TABLE favorite_advertisement( 93 | PRIMARY KEY (account_id,advertisement_id), 94 | account_id INT NOT NULL REFERENCES account(account_id), 95 | advertisement_id INT NOT NULL REFERENCES advertisement(advertisement_id) 96 | ); 97 | 98 | 99 | -- The sample table for the chapter SQL Language 100 | CREATE TABLE a 101 | ( 102 | a_int INT, 103 | a_text TEXT 104 | ); 105 | 106 | CREATE TABLE b 107 | ( 108 | b_int INT UNIQUE, 109 | b_text TEXT 110 | ); 111 | -------------------------------------------------------------------------------- /Chapter04/sql_examples/index.sql: -------------------------------------------------------------------------------- 1 | CREATE TABLE no_date_overlap ( 2 | date_range daterange, 3 | EXCLUDE USING GIST (date_range WITH &&) 4 | ); 5 | INSERT INTO no_date_overlap values('[2010-01-01, 2020-01-01)'); 6 | INSERT INTO no_date_overlap values('[2010-01-01, 2017-01-01)'); 7 | 8 | 9 | --- Check for index selectivity 10 | 11 | SELECT search_key FROM account_history WHERE account_id = GROUP BY search_key ORDER BY max(search_date) limit 10; 12 | 13 | 14 | WITH test_account AS( 15 | INSERT INTO car_portal_app.account 16 | VALUES (1000, 'test_first_name', 'test_last_name','test3@email.com', 'password') RETURNING account_id 17 | ),car AS ( 18 | SELECT i as car_model FROM (VALUES('brand=BMW'), ('brand=VW')) AS foo(i) 19 | ),manufacturing_date AS ( 20 | SELECT 'year='|| i as date FROM generate_series (2015, 2014, -1) as foo(i) 21 | )INSERT INTO car_portal_app.account_history (account_id, search_key, search_date) 22 | SELECT account_id, car.car_model||'&'||manufacturing_date.date, current_date 23 | FROM test_account, car, manufacturing_date; 24 | VACUUM ANALYZE; 25 | 26 | 27 | SELECT search_key FROM car_portal_app.account_history WHERE account_id = 1000 GROUP BY search_key ORDER BY max(search_date) limit 10; 28 | EXPLAIN SELECT search_key FROM car_portal_app.account_history WHERE account_id = 1000 GROUP BY search_key ORDER BY max(search_date) limit 10; 29 | 30 | WITH test_account AS( 31 | INSERT INTO car_portal_app.account 32 | VALUES (2000, 'test_first_name', 'test_last_name','test4@email.com', 'password') RETURNING account_id 33 | ),car AS ( SELECT i as car_model FROM (VALUES('brand=BMW'), ('brand=VW'), ('brand=Audi'), ('brand=MB')) AS foo(i) 34 | ),manufacturing_date AS ( 35 | SELECT 'year='|| i as date FROM generate_series (2017, 1900, -1) as foo(i) 36 | )INSERT INTO account_history (account_id, search_key, search_date) 37 | SELECT account_id, car.car_model||'&'||manufacturing_date.date, current_date 38 | FROM test_account, car, manufacturing_date; 39 | 40 | VACUUM ANALYZE; 41 | EXPLAIN SELECT search_key FROM car_portal_app.account_history WHERE account_id = 2000 GROUP BY search_key ORDER BY max(search_date) limit 10; 42 | 43 | SELECT count(*), account_id FROM car_portal_app.account_history group by account_id; 44 | EXPLAIN SELECT search_key FROM account_history WHERE account_id = 1000 GROUP BY search_key ORDER BY max(search_date) limit 10; 45 | 46 | ---- Index on expressions 47 | CREATE index on car_portal_app.account(lower(first_name)); 48 | 49 | SELECT * FROM car_portal_app.account WHERE lower(first_name) = 'foo'; 50 | 51 | CREATE TABLE employee (employee_id INT PRIMARY KEY, supervisor_id INT); 52 | ALTER TABLE employee ADD CONSTRAINT supervisor_id_fkey FOREIGN KEY 53 | (supervisor_id) REFERENCES employee(employee_id); 54 | CREATE UNIQUE INDEX ON employee ((1)) WHERE supervisor_id IS NULL; 55 | INSERT INTO employee VALUES (1, NULL); 56 | INSERT INTO employee VALUES (2, 1); 57 | INSERT INTO employee VALUES (3, NULL); 58 | 59 | --- Covering index 60 | CREATE TABLE bus_station(id INT, name TEXT , location POINT); 61 | CREATE INDEX ON bus_station(name, location); 62 | CREATE INDEX ON bus_station(name) INCLUDE (location); 63 | CREATE INDEX ON car_portal_app.account (first_name) INCLUDE (last_name); 64 | 65 | --- Index can be duplicated 66 | 67 | CREATE index on car_portal_app.account(first_name); 68 | CREATE index on car_portal_app.account(first_name); 69 | -- Index maintenance 70 | REINDEX index car_portal_app.account_history_account_id_search_key_search_date_key; 71 | CREATE UNIQUE INDEX CONCURRENTLY ON car_portal_app.account_history(account_id, search_key, search_date); 72 | 73 | ALTER TABLE car_portal_app.account_history DROP CONSTRAINT account_history_account_id_search_key_search_date_key; 74 | ALTER TABLE account_history ADD CONSTRAINT account_history_account_id_search_key_search_date_key UNIQUE USING INDEX account_history_account_id_search_key_search_date_idx; -------------------------------------------------------------------------------- /Chapter11/security.sql: -------------------------------------------------------------------------------- 1 | --- Get the content of pg_hba.conf file 2 | SELECT * FROM pg_hba_file_rules limit 1; 3 | 4 | --- PostgreSQL default access privileges 5 | 6 | CREATE ROLE test_user LOGIN; 7 | CREATE DATABASE test 8 | \c test 9 | CREATE TABLE test_permissions(id serial , name text); 10 | SET ROLE test_user; 11 | \d 12 | \du 13 | 14 | SET ROLE postgres; 15 | REVOKE ALL PRIVILEGES ON SCHEMA PUBLIC FROM public; 16 | SET ROLE test_user; 17 | CREATE TABLE b(); 18 | 19 | -- Role system and proxy authentication 20 | 21 | SELECT session_user, current_user; 22 | SET SESSION AUTHORIZATION test_user; 23 | SELECT session_user, current_user; 24 | -- 25 | CREATE ROLE web_app_user LOGIN NOINHERIT; 26 | CREATE ROLE public_user NOLOGIN; 27 | GRANT SELECT ON car_portal_app.advertisement_picture, car_portal_app.advertisement_rating , car_portal_app.advertisement TO public_user; 28 | GRANT public_user TO web_app_user; 29 | GRANT USAGE ON SCHEMA car_portal_app TO web_app_user, public_user; 30 | REVOKE ALL ON DATABASE car_portal FROM public; 31 | GRANT CONNECT ON DATABASE car_portal TO web_app_user; 32 | 33 | --- PostgreSQL security levels 34 | 35 | -- Database permissions 36 | REVOKE ALL ON DATABASE car_portal FROM public; 37 | GRANT CONNECT ON DATABASE car_portal TO web_app_user; 38 | 39 | -- Column permisions 40 | CREATE DATABASE test_column_acl; 41 | \c test_column_acl; 42 | CREATE TABLE test_column_acl AS SELECT * FROM (values (1,2), (3,4)) as n(f1, f2); 43 | CREATE ROLE test_column_acl; 44 | GRANT SELECT (f1) ON test_column_acl TO test_column_acl; 45 | 46 | ---- RLS 47 | CREATE DATABASE test_rls; 48 | \c test_rls 49 | CREATE USER admin; 50 | CREATE USER guest; 51 | CREATE TABLE account ( 52 | account_name NAME, 53 | password TEXT 54 | ); 55 | INSERT INTO account VALUES('admin', 'admin'), ('guest', 'guest'); 56 | GRANT ALL ON account to admin, guest; 57 | ALTER TABLE account ENABLE ROW LEVEL SECURITY; 58 | 59 | SET ROLE admin; 60 | table account; 61 | 62 | CREATE POLICY account_policy_user ON account USING (account_name = current_user); 63 | SET ROLE admin; 64 | table account; 65 | INSERT INTO account values('guest', 'guest'); 66 | 67 | CREATE POLICY account_policy_write_protected ON account USING (true) WITH CHECK (account_name = current_user); 68 | SET ROLE admin; 69 | table account; 70 | CREATE POLICY account_policy_time ON account AS RESTRICTIVE USING ( date_part('hour', statement_timestamp()) BETWEEN 8 AND 16 ) WITH CHECK (account_name = current_user); 71 | 72 | -- Data encryption 73 | CREATE ROLE a password 'a'; ALTER ROLE a RENAME TO b; 74 | \password 75 | 76 | CREATE EXTENSION pgcrypto; 77 | CREATE TABLE account_md5 (id INT, password TEXT); 78 | INSERT INTO account_md5 VALUES (1, md5('my password')); 79 | SELECT (md5('my password') = password) AS authenticated FROM account_md5; 80 | 81 | \df sha* 82 | SELECT sha512('Hello World'); 83 | 84 | CREATE TABLE account_crypt (id INT, password TEXT); 85 | INSERT INTO account_crypt VALUES (1, crypt ('my password', gen_salt('md5'))); 86 | INSERT INTO account_crypt VALUES (2, crypt ('my password', gen_salt('md5'))); 87 | SELECT * FROM account_crypt; 88 | SELECT crypt ('my password', password) = password AS authenticated FROM account_crypt; 89 | 90 | \timing 91 | SELECT crypt('my password', gen_salt('bf',4)); 92 | SELECT crypt('my password', gen_salt('bf',16)); 93 | 94 | 95 | --two-way encryption 96 | \df encrypt 97 | SELECT encrypt ('Hello World', 'Key', 'aes'); 98 | SELECT decrypt(encrypt ('Hello World', 'Key', 'aes'),'Key','aes'); 99 | SELECT convert_from(decrypt(encrypt ('Hello World', 'Key', 'aes'),'Key','aes'), 'utf-8'); 100 | 101 | 102 | --A symetric two-way encryption 103 | CREATE OR REPLACE FUNCTION encrypt (text) RETURNS bytea AS 104 | $$ 105 | BEGIN 106 | RETURN pgp_pub_encrypt($1, dearmor(pg_read_file('public.key'))); 107 | END; 108 | $$ Language plpgsql; 109 | CREATE OR REPLACE FUNCTION decrypt (bytea) RETURNS text AS 110 | $$ 111 | BEGIN 112 | RETURN pgp_pub_decrypt($1, dearmor(pg_read_file('secret.key'))); 113 | END; 114 | $$ Language plpgsql; 115 | 116 | SELECT substring(encrypt('Hello World'), 1, 50); 117 | SELECT decrypt(encrypt('Hello World')); -------------------------------------------------------------------------------- /Chapter04/sql_examples/trigger.sql: -------------------------------------------------------------------------------- 1 | CREATE OR REPLACE FUNCTION car_portal_app.car_log_trg () RETURNS TRIGGER AS 2 | $$ 3 | BEGIN 4 | IF TG_OP = 'INSERT' THEN 5 | INSERT INTO car_portal_app.car_log SELECT NEW.*, 'I', NOW(); 6 | ELSIF TG_OP = 'UPDATE' THEN 7 | INSERT INTO car_portal_app.car_log SELECT NEW.*, 'U', NOW(); 8 | ELSIF TG_OP = 'DELETE' THEN 9 | INSERT INTO car_portal_app.car_log SELECT OLD.*, 'D', NOW(); 10 | END IF; 11 | RETURN NULL; --ignored since this is after trigger 12 | END; 13 | $$ 14 | LANGUAGE plpgsql; 15 | 16 | CREATE TRIGGER car_log AFTER INSERT OR UPDATE OR DELETE ON car_portal_app.car FOR EACH ROW EXECUTE PROCEDURE car_portal_app.car_log_trg (); 17 | 18 | 19 | SET search_path to car_portal_app; 20 | CREATE extension hstore; 21 | CREATE TABLE car_portal_app.log 22 | ( 23 | schema_name text NOT NULL, 24 | table_name text NOT NULL, 25 | old_row hstore, 26 | new_row hstore, 27 | action TEXT check (action IN ('I','U','D')) NOT NULL, 28 | created_by text NOT NULL, 29 | created_on timestamp without time zone NOT NULL 30 | ); 31 | 32 | CREATE OR REPLACE FUNCTION car_portal_app.log_audit() RETURNS trigger AS $$ 33 | DECLARE 34 | log_row car_portal_app.log; 35 | excluded_columns text[] = NULL; 36 | BEGIN 37 | log_row = ROW (TG_TABLE_SCHEMA::text, TG_TABLE_NAME::text,NULL,NULL,NULL,current_user::TEXT, 38 | current_timestamp); 39 | 40 | IF TG_ARGV[0] IS NOT NULL THEN excluded_columns = TG_ARGV[0]::text[]; END IF; 41 | 42 | IF (TG_OP = 'INSERT') THEN 43 | log_row.new_row = hstore(NEW.*) - excluded_columns; 44 | log_row.action ='I'; 45 | ELSIF (TG_OP = 'UPDATE' AND (hstore(OLD.*) - excluded_columns!= hstore(NEW.*)-excluded_columns)) THEN 46 | log_row.old_row = hstor(OLD.*) - excluded_columns; 47 | log_row.new_row = hstore(NEW.* )- excluded_columns; 48 | log_row.action ='U'; 49 | ELSIF (TG_OP = 'DELETE') THEN 50 | log_row.old_row = hstore (OLD.*) - excluded_columns; 51 | log_row.action ='D'; 52 | ELSE 53 | RETURN NULL; -- update on excluded columns 54 | END IF; 55 | INSERT INTO car_portal_app.log SELECT log_row.*; 56 | RETURN NULL; 57 | END; 58 | $$ LANGUAGE plpgsql; 59 | 60 | CREATE TRIGGER car_log_trg AFTER INSERT OR UPDATE OR DELETE ON car_portal_app.car FOR EACH ROW EXECUTE PROCEDURE car_portal_app.log_audit('{number_of_doors}'); 61 | 62 | INSERT INTO car_portal_app.car (car_id, car_model_id, number_of_owners, registration_number, number_of_doors, manufacture_year) VALUES (default, 2, 2, 'z', 3, 2017); 63 | SELECT jsonb_pretty((to_json(log))::jsonb) FROM car_portal_app.log WHERE action = 'I' and new_row->'registration_number'='z'; 64 | 65 | CREATE OR REPLACE VIEW car_portal_app.seller_account_info AS 66 | SELECT account.account_id, first_name, last_name, email, password, seller_account_id, total_rank, number_of_advertisement, street_name, street_number, zip_code , city 67 | FROM car_portal_app.account INNER JOIN 68 | car_portal_app.seller_account ON (account.account_id = seller_account.account_id); 69 | 70 | 71 | SELECT is_insertable_into FROM information_schema.tables WHERE table_name = 'seller_account_info'; 72 | 73 | CREATE OR REPLACE FUNCTION car_portal_app.seller_account_info_update () RETURNS TRIGGER AS $$ 74 | DECLARE 75 | acc_id INT; 76 | seller_acc_id INT; 77 | BEGIN 78 | IF (TG_OP = 'INSERT') THEN 79 | WITH inserted_account AS ( 80 | INSERT INTO car_portal_app.account (account_id, first_name, last_name, password, email) VALUES (DEFAULT, NEW.first_name, NEW.last_name, NEW.password, NEW.email) RETURNING account_id 81 | ), inserted_seller_account AS ( 82 | INSERT INTO car_portal_app.seller_account(seller_account_id, account_id, total_rank, number_of_advertisement, street_name, street_number, zip_code, city) 83 | SELECT nextval('car_portal_app.seller_account_seller_account_id_seq'::regclass), account_id, NEW.total_rank, NEW.number_of_advertisement, NEW.street_name, NEW.street_number, NEW.zip_code, NEW.city FROM inserted_account RETURNING account_id, seller_account_id) 84 | SELECT account_id, seller_account_id INTO acc_id, seller_acc_id FROM inserted_seller_account; 85 | NEW.account_id = acc_id; 86 | NEW.seller_account_id = seller_acc_id; 87 | RETURN NEW; 88 | ELSIF (TG_OP = 'UPDATE' AND OLD.account_id = NEW.account_id AND OLD.seller_account_id = NEW.seller_account_id) THEN 89 | UPDATE car_portal_app.account SET first_name = new.first_name, last_name = new.last_name, password= new.password, email = new.email WHERE account_id = new.account_id; 90 | UPDATE car_portal_app.seller_account SET total_rank = NEW.total_rank, number_of_advertisement= NEW.number_of_advertisement, street_name= NEW.street_name, street_number = NEW.street_number, zip_code = NEW.zip_code, city = NEW.city WHERE seller_account_id = NEW.seller_account_id; 91 | RETURN NEW; 92 | ELSIF (TG_OP = 'DELETE') THEN 93 | DELETE FROM car_portal_app.seller_account WHERE seller_account_id = OLD.seller_account_id; 94 | DELETE FROM car_portal_app.account WHERE account_id = OLD.account_id; 95 | RETURN OLD; 96 | ELSE 97 | RAISE EXCEPTION 'An error occurred for % operation', TG_OP; 98 | RETURN NULL; 99 | END IF; 100 | END; 101 | $$ LANGUAGE plpgsql; 102 | 103 | CREATE TRIGGER seller_account_info_trg INSTEAD OF INSERT OR UPDATE OR DELETE ON car_portal_app.seller_account_info FOR EACH ROW EXECUTE PROCEDURE seller_account_info_update (); 104 | 105 | INSERT INTO car_portal_app.seller_account_info (first_name,last_name, password, email, total_rank, number_of_advertisement, street_name, street_number, zip_code, city) VALUES ('test_first_name', 'test_last_name', 'test_password', 'test_email@test.com', NULL, 0, 'test_street_name', 'test_street_number', 'test_zip_code','test_city') RETURNING account_id, seller_account_id; 106 | 107 | UPDATE car_portal_app.seller_account_info set email = 'test2@test.com' WHERE seller_account_id=147 RETURNING seller_account_id; 108 | 109 | DELETE FROM car_portal_app.seller_account_info WHERE seller_account_id=147; 110 | DELETE FROM car_portal_app.seller_account_info; -------------------------------------------------------------------------------- /README.md: -------------------------------------------------------------------------------- 1 | # Learning PostgreSQL 11 - Third Edition 2 | 3 | Learning PostgreSQL 11 - Third Edition 4 | 5 | This is the code repository for [Learning PostgreSQL 11 - Third Edition](https://www.packtpub.com/big-data-and-business-intelligence/learning-postgresql-11-third-edition?utm_source=github&utm_medium=repository&utm_campaign=9781789535464 ), published by Packt. 6 | 7 | **A beginner's guide to building high-performance PostgreSQL database solutions** 8 | 9 | ## What is this book about? 10 | PostgreSQL is one of the most popular open source database management systems in the world, and it supports advanced features included in SQL standards. This book will familiarize you with the latest features in PostgreSQL 11, and get you up and running with building efficient PostgreSQL database solutions from scratch. 11 | 12 | This book covers the following exciting features: 13 | Understand the basics of relational databases, relational algebra, and data modeling 14 | Install a PostgreSQL server, create a database, and implement your data model 15 | Create tables and views, define indexes and stored procedures, and implement triggers 16 | Make use of advanced data types such as Arrays, hstore, and JSONB 17 | Connect your Python applications to PostgreSQL and work with data efficiently 18 | Identify bottlenecks to enhance reliability and performance of database applications 19 | 20 | If you feel this book is for you, get your [copy](https://www.amazon.com/dp/1789535468) today! 21 | 22 | https://www.packtpub.com/ 24 | 25 | ## Instructions and Navigations 26 | All of the code is organized into folders. For example, Chapter02. 27 | 28 | The code will look like the following: 29 | ``` 30 | log_destination = 'csvlog' 31 | logging_collector = on 32 | log_filename = 'postgresql.log' 33 | log_statement = 'all' 34 | ``` 35 | 36 | **Following is what you need for this book:** 37 | This book is for you if you're interested in learning about PostgreSQL from scratch. Those looking to build solid database or data warehousing applications or wanting to get up to speed with the latest features of PostgreSQL 11 will also find this book useful. No prior knowledge of database programming or administration is required to get started. 38 | 39 | With the following software and hardware list you can run all code files present in the book (Chapter 1-17). 40 | ### Software and Hardware List 41 | | Chapter | Software required | OS required | 42 | | -------- | ------------------------------------ | ----------------------------------- | 43 | | 1-16 | PostgreSQL version 11, PostgreSQL client tool | Windows, Mac OS X, and Linux (Any) | 44 | | 15 | Python 3.x | Windows, Mac OS X, and Linux (Any) | 45 | | 16 | Docker | Windows, Mac OS X, and Linux (Any) | 46 | 47 | We also provide a PDF file that has color images of the screenshots/diagrams used in this book. [Click here to download it](https://www.packtpub.com/sites/default/files/downloads/9781789535464_ColorImages.pdf). 48 | 49 | ### Related products 50 | * Mastering PostgreSQL 11 - Second Edition [[Packt]](https://www.packtpub.com/big-data-and-business-intelligence/mastering-postgresql-11-second-edition?utm_source=github&utm_medium=repository&utm_campaign=9781789537819 ) [[Amazon]](https://www.amazon.com/dp/B07J5TLQ3Y) 51 | 52 | * PostgreSQL 10 Administration Cookbook [[Packt]](https://www.packtpub.com/big-data-and-business-intelligence/postgresql-10-administration-cookbook?utm_source=github&utm_medium=repository&utm_campaign=9781788474924 ) [[Amazon]](https://www.amazon.com/dp/B07D9R6DVL) 53 | 54 | 55 | ## Get to Know the Author 56 | **Salahaldin Juba** 57 | has over than a decade of experience in the industry and academia, with a focus on database development for large-scale and enterprise applications. He holds a master's degree of science in environmental management with a distinction, and a bachelor's degree of engineering in computer systems. He is also a Microsoft Certified Solution Developer (MCSD). 58 | He has worked mainly with SQL server, PostgreSQL, and Greenplum databases. As a software engineer, he works mainly with defining ETL processes with external parties, promoting SQL best practices, designing OLTP and OLAP applications, and providing training and consultation services. 59 | 60 | **Andrey Volkov** 61 | studied information systems in banking, and started his career as a financial analyst in a commercial bank. He joined a data warehouse team, and after some time, he lead the team by taking the position of the data warehouse architect. 62 | There he worked mainly with Oracle database stack and used it to develop logical and physical models of financial and accounting data, implement them in the database, develop ETL processes, and perform analytical tasks. 63 | Now Andrey works as a senior database developer in a telecommunication provider. Here, he works mainly with PostgreSQL databases, being responsible for data modeling, developing a data warehouse, reporting and billing systems. 64 | 65 | 66 | ## Other books by the authors 67 | [Learning PostgreSQL](https://www.packtpub.com/big-data-and-business-intelligence/learning-postgresql?utm_source=github&utm_medium=repository&utm_campaign=9781783989188 ) 68 | 69 | [Learning PostgreSQL 10 - Second Edition](https://www.packtpub.com/big-data-and-business-intelligence/learning-postgresql-10-second-edition?utm_source=github&utm_medium=repository&utm_campaign=9781788392013 ) 70 | 71 | ### Suggestions and Feedback 72 | [Click here](https://docs.google.com/forms/d/e/1FAIpQLSdy7dATC6QmEL81FIUuymZ0Wy9vH1jHkvpY57OiMeKGqib_Ow/viewform) if you have any feedback or suggestions. 73 | 74 | 75 | -------------------------------------------------------------------------------- /Chapter10/transaction.sql: -------------------------------------------------------------------------------- 1 | BEGIN; 2 | CREATE TABLE employee (id serial primary key, name text, salary numeric); 3 | COMMIT; 4 | 5 | BEGIN; 6 | UPDATE employee set salary = salary*1.1; 7 | SAVEPOINT increase_salary; 8 | UPDATE employee set salary = salary + 500 WHERE name =’john’; 9 | ROLLBACK to increase_salary; 10 | COMMIT; 11 | 12 | 13 | SELECT txid_current(); 14 | SELECT 1; 15 | SELECT txid_current(); 16 | 17 | BEGIN; 18 | SELECT txid_current(); 19 | SELECT 1; 20 | SELECT txid_current(); 21 | 22 | CREATE TABLE test_tx_level AS SELECT 1 as val; 23 | 24 | -------------------------------------------------- repeatable read 25 | --- session 1 26 | BEGIN; 27 | SELECT * FROM test_tx_level ; 28 | 29 | --- session 2 30 | BEGIN; 31 | UPDATE test_tx_level SET val = 2; 32 | COMMIT; 33 | 34 | --- session1 35 | SELECT * FROM test_tx_level ; 36 | COMMIT; 37 | 38 | 39 | -------------------------------------------------- phantom read 40 | --- session 1 41 | BEGIN; 42 | SELECT count(*) FROM test_tx_level ; 43 | 44 | --- session 2 45 | BEGIN; 46 | INSERT INTO test_tx_level SELECT 2; 47 | COMMIT; 48 | 49 | --- session1 50 | SELECT count(*) FROM test_tx_level ; 51 | COMMIT; 52 | 53 | 54 | 55 | -------------------------------------------------- phantom read /serializable 56 | --- session 1 57 | BEGIN TRANSACTION ISOLATION LEVEL SERIALIZABLE ; 58 | SELECT count(*) FROM test_tx_level ; 59 | 60 | --- session 2 61 | BEGIN; 62 | INSERT INTO test_tx_level SELECT 2; 63 | COMMIT; 64 | 65 | --- session1 66 | SELECT count(*) FROM test_tx_level ; 67 | COMMIT; 68 | 69 | 70 | ---------------------------------------------- Repeatabl read anamoly 71 | CREATE TABLE zero_or_one (val int); 72 | INSERT INTO zero_or_one SELECT n % 2 FROM generate_series(1,10) as foo(n) ; 73 | SELECT array_agg(val) FROM zero_or_one ; 74 | 75 | 76 | -- session 1 77 | BEGIN TRANSACTION ISOLATION LEVEL REPEATABLE READ ; 78 | UPDATE zero_or_one SET val = 1 WHERE val = 0; 79 | --- session 2 80 | BEGIN TRANSACTION ISOLATION LEVEL REPEATABLE READ ; 81 | UPDATE zero_or_one SET val =0 WHERE val =1; 82 | COMMIT; 83 | -- session 1 84 | COMMIT; 85 | 86 | SELECT * FROM zero_or_one ; 87 | 88 | 89 | ---------------------------------------------- with serializable 90 | truncate zero_or_one ; 91 | INSERT INTO zero_or_one SELECT n % 2 FROM generate_series(1,10) as foo(n) ; 92 | 93 | 94 | 95 | --- sesion 1 96 | BEGIN TRANSACTION ISOLATION LEVEL SERIALIZABLE ; 97 | UPDATE zero_or_one SET val = 1 WHERE val = 0; 98 | 99 | --- session2 100 | BEGIN TRANSACTION ISOLATION LEVEL SERIALIZABLE ; 101 | UPDATE zero_or_one SET val =0 WHERE val =1; 102 | COMMIT; 103 | --- 104 | 105 | SELECT array_agg(val) FROM zero_or_one ; 106 | 107 | --------------------------------------------- Lock level 108 | --- session1 109 | BEGIN; 110 | SELECT COUNT(*) FROM test_tx_level ; 111 | SELECT mode, granted FROM pg_locks where relation ='test_tx_level'::regclass::oid; 112 | 113 | --- Session 2 114 | 115 | BEGIN; 116 | DROP TABLE test_tx_level; 117 | 118 | --- session1 119 | SELECT mode, granted FROM pg_locks where relation ='test_tx_level'::regclass::oid; 120 | 121 | 122 | -------------------------------------------- pg_locks info 123 | 124 | CREATE OR REPLACE VIEW lock_info AS 125 | SELECT 126 | lock1.pid as locked_pid, 127 | stat1.usename as locked_user, 128 | stat1.query as locked_statement, 129 | stat1.state as locked_statement_state, 130 | stat2.query as locking_statement, 131 | stat2.state as locking_statement_state, 132 | now() - stat1.query_start as locking_duration, 133 | lock2.pid as locking_pid, 134 | stat2.usename as locking_user 135 | FROM pg_catalog.pg_locks lock1 136 | JOIN pg_catalog.pg_stat_activity stat1 on lock1.pid = stat1.pid 137 | JOIN pg_catalog.pg_locks lock2 on 138 | (lock1.locktype,lock1.database,lock1.relation,lock1.page,lock1.tuple,lock1.virtualxid,lock1.transactionid,lock1.classid,lock1.objid,lock1.objsubid) IS NOT DISTINCT FROM 139 | (lock2.locktype,lock2.DATABASE,lock2.relation,lock2.page,lock2.tuple,lock2.virtualxid,lock2.transactionid,lock2.classid,lock2.objid,lock2.objsubid) 140 | JOIN pg_catalog.pg_stat_activity stat2 on lock2.pid = stat2.pid 141 | WHERE NOT lock1.granted AND lock2.granted; 142 | 143 | SELECT * FROM lock_info 144 | 145 | 146 | ----------------------------------------- row level locks 147 | 148 | truncate test_tx_level ; 149 | insert into test_tx_level Values(1), (2); 150 | 151 | 152 | --- Session 1 153 | BEGIN; 154 | SELECT * FROM test_tx_level WHERE val = 1 FOR update; 155 | 156 | --- Session2 157 | BEGIN; 158 | update test_tx_level SET val =2 WHERE val =1; 159 | 160 | SELECT * FROM lock_info ; 161 | 162 | 163 | --------------------------------------- deadlock 164 | 165 | --- session 1 166 | begin; 167 | SELECT * FROM test_tx_level WHERE val = 1 FOR SHARE; 168 | 169 | ---session 2 170 | begin; 171 | SELECT * FROM test_tx_level WHERE val = 1 FOR SHARE; 172 | 173 | --- session 1 174 | UPDATE test_tx_level SET val = 2 WHERE val=1; 175 | 176 | --- session 2 177 | UPDATE test_tx_level SET val = 2 WHERE val=1; 178 | 179 | ------------------------------------------advisory locks 180 | 181 | --- session1 182 | SELECT pg_try_advisory_lock(1); 183 | 184 | --- session2 185 | SELECT pg_try_advisory_lock(1); 186 | 187 | --- session 1 188 | select pg_advisory_unlock(1); 189 | 190 | --- session2 191 | SELECT pg_try_advisory_lock(1); 192 | 193 | ------------------------------ 194 | SELECT pg_try_advisory_lock(1); 195 | SELECT pg_try_advisory_lock(1); 196 | -- To release 197 | select pg_advisory_unlock(1); 198 | select pg_advisory_unlock(1); 199 | 200 | ------------------------------------------Transaction in functions and procedure 201 | CREATE TABLE test_tx_procedure (a int); 202 | 203 | CREATE PROCEDURE test_tx_procedure() 204 | AS $$ 205 | BEGIN 206 | FOR i IN 0..4 LOOP 207 | INSERT INTO test_tx_procedure (a) VALUES (i); 208 | IF i % 2 = 0 THEN 209 | RAISE NOTICE 'i=%, txid=% will be committed', i, txid_current(); 210 | COMMIT; 211 | ELSE 212 | RAISE NOTICE 'i=%, txid=% will be rolledback', i, txid_current(); 213 | ROLLBACK; 214 | END IF; 215 | END LOOP; 216 | END 217 | $$ 218 | LANGUAGE PLPGSQL; 219 | call test_tx_procedure(); 220 | 221 | -------------------------------------------------------------------------------- /Chapter14/Testing/examples.sql: -------------------------------------------------------------------------------- 1 | CREATE TABLE counter_table(counter int); 2 | 3 | CREATE FUNCTION increment_counter() RETURNS void AS $$ 4 | BEGIN 5 | INSERT INTO counter_table SELECT count(*) FROM counter_table; 6 | END; 7 | $$ LANGUAGE plpgsql; 8 | 9 | ---------------------------------------------------------------- 10 | 11 | CREATE PROCEDURE test_increment() AS $$ 12 | DECLARE 13 | c int; m int; 14 | BEGIN 15 | RAISE NOTICE '1..2'; 16 | -- Test 1. Call the increment function 17 | BEGIN 18 | PERFORM increment_counter(); 19 | RAISE NOTICE 'ok 1 - Call increment function'; 20 | EXCEPTION WHEN OTHERS THEN 21 | RAISE NOTICE 'not ok 1 - Call increment function'; 22 | END; 23 | -- Test 2. The results are correct 24 | BEGIN 25 | SELECT COUNT(*), MAX(counter) INTO c, m FROM counter_table; 26 | IF NOT (c = 1 AND m = 0) THEN 27 | RAISE EXCEPTION 'Test 2: wrong values in output data'; 28 | END IF; 29 | RAISE NOTICE 'ok 2 - Results are correct'; 30 | EXCEPTION WHEN OTHERS THEN 31 | RAISE NOTICE 'not ok 2 - Results are correct'; 32 | END; 33 | ROLLBACK; 34 | END; 35 | $$ LANGUAGE plpgsql; 36 | 37 | ---------------------------------------------------------------- 38 | 39 | CALL test_increment(); 40 | 41 | ---------------------------------------------------------------- 42 | 43 | ALTER TABLE counter_table ADD insert_time timestamp with time zone NOT NULL; 44 | 45 | ---------------------------------------------------------------- 46 | 47 | CALL test_increment(); 48 | 49 | ---------------------------------------------------------------- 50 | 51 | CREATE OR REPLACE FUNCTION increment_counter() RETURNS void AS $$ 52 | BEGIN 53 | INSERT INTO counter_table SELECT count(*), now() FROM counter_table; 54 | END; 55 | $$ LANGUAGE plpgsql; 56 | 57 | ---------------------------------------------------------------- 58 | 59 | CALL test_increment(); 60 | 61 | ---------------------------------------------------------------- 62 | 63 | CREATE OR REPLACE PROCEDURE test_increment() AS $$ 64 | DECLARE 65 | c int; m int; 66 | msg_text text; exception_detail text; exception_hint text; 67 | BEGIN 68 | RAISE NOTICE '1..3'; 69 | -- Test 1. Call increment function 70 | BEGIN 71 | PERFORM increment_counter(); 72 | RAISE NOTICE 'ok 1 - Call increment function'; 73 | EXCEPTION WHEN OTHERS THEN 74 | RAISE NOTICE 'not ok 1 - Call increment function'; 75 | GET STACKED DIAGNOSTICS 76 | msg_text = MESSAGE_TEXT, 77 | exception_detail = PG_EXCEPTION_DETAIL, 78 | exception_hint = PG_EXCEPTION_HINT; 79 | RAISE NOTICE 'Exception: % % %', msg_text, exception_detail, exception_hint; 80 | END; 81 | -- Test 2. The results are correct for the first record 82 | BEGIN 83 | SELECT COUNT(*), MAX(counter) INTO c, m FROM counter_table; 84 | IF NOT (c = 1 AND m = 0) THEN 85 | RAISE EXCEPTION 'Test 2: wrong values in output data for the first record'; 86 | END IF; 87 | RAISE NOTICE 'ok 2 - The results are correct for the first record'; 88 | EXCEPTION WHEN OTHERS THEN 89 | RAISE NOTICE 'not ok 2 - The results are correct for the first record'; 90 | GET STACKED DIAGNOSTICS 91 | msg_text = MESSAGE_TEXT, 92 | exception_detail = PG_EXCEPTION_DETAIL, 93 | exception_hint = PG_EXCEPTION_HINT; 94 | RAISE NOTICE 'Exception: % % %', msg_text, exception_detail, exception_hint; 95 | END; 96 | -- Test 3. The results are correct for the second record 97 | BEGIN 98 | PERFORM increment_counter(); 99 | SELECT COUNT(*), MAX(counter) INTO c, m FROM counter_table; 100 | IF NOT (c = 2 AND m = 1) THEN 101 | RAISE EXCEPTION 'Test 3: wrong values in output data for the second record'; 102 | END IF; 103 | RAISE NOTICE 'ok 3 - The results are correct for the second record'; 104 | EXCEPTION WHEN OTHERS THEN 105 | RAISE NOTICE 'not ok 3 - The results are correct for the second record'; 106 | GET STACKED DIAGNOSTICS 107 | msg_text = MESSAGE_TEXT, 108 | exception_detail = PG_EXCEPTION_DETAIL, 109 | exception_hint = PG_EXCEPTION_HINT; 110 | RAISE NOTICE 'Exception: % % %', msg_text, exception_detail, exception_hint; 111 | END; 112 | ROLLBACK; 113 | END; 114 | $$ LANGUAGE plpgsql; 115 | 116 | ---------------------------------------------------------------- 117 | 118 | CREATE EXTENSION pgtap; 119 | 120 | \t 121 | \i pgtap.sql 122 | \t 123 | 124 | ---------------------------------------------------------------- 125 | 126 | SET role postgres; 127 | \c postgres 128 | DROP DATABASE IF EXISTS car_portal_new; 129 | CREATE DATABASE car_portal_new TEMPLATE car_portal OWNER car_portal_app; 130 | \c car_portal_new 131 | 132 | ---------------------------------------------------------------- 133 | 134 | ALTER TABLE car_portal_app.car ADD insert_date timestamp with time zone DEFAULT now(); 135 | 136 | ---------------------------------------------------------------- 137 | 138 | CREATE EXTENSION postgres_fdw ; 139 | 140 | ---------------------------------------------------------------- 141 | 142 | CREATE SERVER car_portal_original FOREIGN DATA WRAPPER postgres_fdw OPTIONS (host 'localhost', dbname 'car_portal'); 143 | 144 | ---------------------------------------------------------------- 145 | 146 | CREATE USER MAPPING FOR CURRENT_USER SERVER car_portal_original; 147 | 148 | ---------------------------------------------------------------- 149 | 150 | CREATE FOREIGN TABLE car_portal_app.car_orignal (car_id int, number_of_owners int, registration_number text, 151 | manufacture_year int, number_of_doors int, car_model_id int, mileage int) 152 | SERVER car_portal_original OPTIONS (table_name 'car'); 153 | 154 | ---------------------------------------------------------------- 155 | 156 | SELECT car_id FROM car_portal_app.car_orignal limit 1; 157 | 158 | ---------------------------------------------------------------- 159 | 160 | WITH n AS ( 161 | SELECT car_id, number_of_owners, registration_number, manufacture_year, number_of_doors, 162 | car_model_id, mileage 163 | FROM car_portal_app.car), 164 | o AS (SELECT * FROM car_portal_app.car_orignal) 165 | SELECT 'new', * FROM (SELECT * FROM n EXCEPT ALL SELECT * FROM o) a 166 | UNION ALL 167 | SELECT 'old', * FROM (SELECT * FROM o EXCEPT ALL SELECT * FROM n) b; 168 | 169 | ---------------------------------------------------------------- 170 | 171 | \c car_portal 172 | SET ROLE car_portal_app; 173 | 174 | ---------------------------------------------------------------- 175 | 176 | \timing 177 | SELECT count(*) FROM car_portal_app.car; 178 | -------------------------------------------------------------------------------- /Chapter08/OLAP and data warehousing/examples.sql: -------------------------------------------------------------------------------- 1 | --------------------------------------------------- 2 | 3 | CREATE TABLE dwh.access_log 4 | ( 5 | ts timestamp with time zone, 6 | remote_address text, 7 | remote_user text, 8 | url text, 9 | status_code int, 10 | body_size int, 11 | http_referer text, 12 | http_user_agent text 13 | ); 14 | 15 | --------------------------------------------------- 16 | 17 | \copy dwh.access_log FROM 'access.log' WITH csv delimiter ';' 18 | 19 | --------------------------------------------------- 20 | 21 | ALTER TABLE dwh.access_log ADD car_id int; 22 | 23 | --------------------------------------------------- 24 | 25 | UPDATE dwh.access_log SET car_id = (SELECT regexp_matches(url, '/api/cars/(\d+)\W'))[1]::int WHERE url like '%/api/cars/%'; 26 | 27 | --------------------------------------------------- 28 | 29 | CREATE TABLE dwh.access_log_partitioned (ts timestamptz, url text, status_code int) 30 | PARTITION BY RANGE (ts); 31 | 32 | --------------------------------------------------- 33 | 34 | CREATE TABLE dwh.access_log_2018_07 PARTITION OF dwh.access_log_partitioned 35 | FOR VALUES FROM ('2018-07-01') TO ('2018-08-01'); 36 | 37 | CREATE TABLE dwh.access_log_2018_08 PARTITION OF dwh.access_log_partitioned 38 | FOR VALUES FROM ('2018-08-01') TO ('2018-09-01'); 39 | 40 | CREATE TABLE dwh.access_log_2018_09 PARTITION OF dwh.access_log_partitioned 41 | FOR VALUES FROM ('2018-09-01') TO ('2018-10-01'); 42 | 43 | --------------------------------------------------- 44 | -- expected to FAIL 45 | INSERT INTO dwh.access_log_partitioned values ('2018-02-01', '/test', 404); 46 | 47 | --------------------------------------------------- 48 | 49 | CREATE TABLE dwh.access_log_min PARTITION OF dwh.access_log_partitioned 50 | FOR VALUES FROM (MINVALUE) TO ('2018-07-01'); 51 | 52 | --------------------------------------------------- 53 | 54 | CREATE TABLE dwh.access_log_default PARTITION OF dwh.access_log_partitioned DEFAULT; 55 | 56 | --------------------------------------------------- 57 | 58 | CREATE TABLE dwh.access_log_2018_10 PARTITION OF dwh.access_log_partitioned 59 | FOR VALUES FROM ('2018-10-01') TO ('2018-11-01') 60 | PARTITION BY LIST (status_code); 61 | 62 | CREATE TABLE dwh.access_log_2018_10_200 PARTITION OF dwh.access_log_2018_10 FOR VALUES IN (200); 63 | 64 | CREATE TABLE dwh.access_log_2018_10_400 PARTITION OF dwh.access_log_2018_10 FOR VALUES IN (400); 65 | 66 | --------------------------------------------------- 67 | 68 | CREATE TABLE dwh.access_log_2018_11 PARTITION OF dwh.access_log_partitioned 69 | FOR VALUES FROM ('2018-11-01') TO ('2018-12-01') 70 | PARTITION BY LIST (left(status_code::text, 1)); 71 | 72 | CREATE TABLE dwh.access_log_2018_11_2XX PARTITION OF dwh.access_log_2018_11 FOR VALUES IN ('2'); 73 | 74 | CREATE TABLE dwh.access_log_2018_11_4XX PARTITION OF dwh.access_log_2018_11 FOR VALUES IN ('4'); 75 | 76 | --------------------------------------------------- 77 | 78 | CREATE TABLE dwh.access_log_2018_12 PARTITION OF dwh.access_log_partitioned 79 | FOR VALUES FROM ('2018-12-01') TO ('2019-01-01') 80 | PARTITION BY HASH (url); 81 | 82 | CREATE TABLE dwh.access_log_2018_12_1 PARTITION OF dwh.access_log_2018_12 FOR VALUES WITH (MODULUS 3, REMAINDER 0); 83 | 84 | CREATE TABLE dwh.access_log_2018_12_2 PARTITION OF dwh.access_log_2018_12 FOR VALUES WITH (MODULUS 3, REMAINDER 1); 85 | 86 | CREATE TABLE dwh.access_log_2018_12_3 PARTITION OF dwh.access_log_2018_12 FOR VALUES WITH (MODULUS 3, REMAINDER 2); 87 | 88 | --------------------------------------------------- 89 | 90 | ALTER TABLE dwh.access_log_partitioned DETACH PARTITION dwh.access_log_2018_11; 91 | 92 | --------------------------------------------------- 93 | 94 | ALTER TABLE dwh.access_log_partitioned ATTACH PARTITION dwh.access_log_2018_11 95 | FOR VALUES FROM ('2018-11-01') TO ('2018-12-01'); 96 | 97 | --------------------------------------------------- 98 | 99 | CREATE TABLE dwh.access_log_not_partitioned (LIKE dwh.access_log_partitioned); 100 | 101 | --------------------------------------------------- 102 | 103 | INSERT INTO dwh.access_log_not_partitioned SELECT ts, url, status_code FROM dwh.access_log, generate_series(1, 1000); 104 | INSERT INTO dwh.access_log_partitioned SELECT ts, url, status_code FROM dwh.access_log, generate_series(1, 1000); 105 | 106 | --------------------------------------------------- 107 | 108 | \timing 109 | SELECT count(*) FROM dwh.access_log_not_partitioned WHERE ts >= '2018-08-22' AND ts < '2018-09-01'; 110 | SELECT count(*) FROM dwh.access_log_partitioned WHERE ts >= '2018-08-22' AND ts < '2018-09-01'; 111 | 112 | --------------------------------------------------- 113 | 114 | EXPLAIN SELECT count(*) FROM dwh.access_log_partitioned WHERE ts >= '2018-08-22' AND ts < '2018-09-01'; 115 | 116 | --------------------------------------------------- 117 | 118 | SET max_parallel_workers_per_gather = 0; 119 | 120 | --------------------------------------------------- 121 | 122 | SELECT count(*) FROM dwh.access_log_not_partitioned WHERE url ~ 'car'; 123 | 124 | --------------------------------------------------- 125 | 126 | SET max_parallel_workers_per_gather = 1; 127 | 128 | --------------------------------------------------- 129 | 130 | SELECT count(*) FROM dwh.access_log_not_partitioned WHERE url ~ 'car'; 131 | 132 | --------------------------------------------------- 133 | 134 | CREATE INDEX ON dwh.access_log_not_partitioned (ts, status_code); 135 | 136 | --------------------------------------------------- 137 | 138 | SELECT min(ts) FROM dwh.access_log_not_partitioned WHERE ts BETWEEN '2018-08-01' AND '2018-08-02' AND status_code = '201'; 139 | 140 | --------------------------------------------------- 141 | 142 | EXPLAIN SELECT min(ts) FROM dwh.access_log_not_partitioned WHERE ts BETWEEN '2018-08-01' AND '2018-08-02' AND status_code = '201'; 143 | 144 | --------------------------------------------------- 145 | 146 | SET enable_indexonlyscan = off; 147 | 148 | --------------------------------------------------- 149 | 150 | SELECT min(ts) FROM dwh.access_log_not_partitioned WHERE ts BETWEEN '2018-08-01' AND '2018-08-02' AND status_code = '201'; 151 | 152 | --------------------------------------------------- 153 | 154 | EXPLAIN SELECT min(ts) FROM dwh.access_log_not_partitioned WHERE ts BETWEEN '2018-08-01' AND '2018-08-02' AND status_code = '201'; 155 | 156 | --------------------------------------------------- 157 | 158 | CREATE INDEX ON dwh.access_log_not_partitioned (ts) WHERE status_code = 201; 159 | EXPLAIN SELECT min(ts) FROM dwh.access_log_not_partitioned WHERE ts BETWEEN '2018-08-01' AND '2018-08-02' AND status_code = '201'; 160 | 161 | --------------------------------------------------- 162 | 163 | CREATE INDEX ON dwh.access_log_partitioned (ts) INCLUDE (url); 164 | EXPLAIN SELECT DISTINCT url FROM dwh.access_log_partitioned WHERE ts BETWEEN '2018-07-15' AND '2018-08-15'; -------------------------------------------------------------------------------- /Chapter06/Advanced Query Writing/examples.sql: -------------------------------------------------------------------------------- 1 | ---------------------------------------------------------------------- 2 | 3 | WITH pre_select AS 4 | ( 5 | SELECT car_id, number_of_owners, car_model_id 6 | FROM car_portal_app.car WHERE manufacture_year >= 2010 7 | ), 8 | joined_data AS 9 | ( 10 | SELECT car_id, make, model, number_of_owners 11 | FROM pre_select 12 | INNER JOIN car_portal_app.car_model ON pre_select.car_model_id = car_model.car_model_id 13 | ), 14 | minimal_owners AS (SELECT min(number_of_owners) AS min_number_of_owners FROM pre_select) 15 | SELECT car_id, make, model, number_of_owners 16 | FROM joined_data INNER JOIN minimal_owners 17 | ON joined_data.number_of_owners = minimal_owners.min_number_of_owners; 18 | 19 | ---------------------------------------------------------------------- 20 | 21 | SELECT make, model, avg_age FROM 22 | ( 23 | SELECT car_model_id, avg(EXTRACT(YEAR FROM now())-manufacture_year) AS avg_age 24 | FROM car_portal_app.car 25 | GROUP BY car_model_id 26 | ) age_subq1 27 | INNER JOIN car_portal_app.car_model ON car_model.car_model_id = age_subq1.car_model_id 28 | WHERE avg_age < (SELECT avg(avg_age) FROM 29 | ( 30 | SELECT avg(EXTRACT(YEAR FROM now()) - manufacture_year) avg_age 31 | FROM car_portal_app.car 32 | GROUP BY car_model_id 33 | ) age_subq2 34 | ); 35 | 36 | ---------------------------------------------------------------------- 37 | 38 | WITH age_subq AS 39 | ( 40 | SELECT car_model_id, avg(EXTRACT(YEAR FROM now())-manufacture_year) AS avg_age 41 | FROM car_portal_app.car 42 | GROUP BY car_model_id 43 | ) 44 | SELECT make, model, avg_age 45 | FROM age_subq 46 | INNER JOIN car_portal_app.car_model ON car_model.car_model_id = age_subq.car_model_id 47 | WHERE avg_age < (SELECT avg(avg_age) FROM age_subq); 48 | 49 | ---------------------------------------------------------------------- 50 | 51 | WITH car_subquery AS 52 | (SELECT number_of_owners, manufacture_year, number_of_doors FROM car_portal_app.car) 53 | SELECT number_of_owners, number_of_doors FROM car_subquery WHERE manufacture_year = 2008; 54 | 55 | ---------------------------------------------------------------------- 56 | 57 | SELECT number_of_owners, manufacture_year, number_of_doors 58 | FROM car_portal_app.car 59 | WHERE manufacture_year = 2008; 60 | 61 | ---------------------------------------------------------------------- 62 | 63 | WITH RECURSIVE subq (n, factorial) AS 64 | ( 65 | SELECT 1, 1 66 | UNION ALL 67 | SELECT n + 1, factorial * (n + 1) from subq WHERE n < 5 68 | ) 69 | SELECT * FROM subq; 70 | 71 | ---------------------------------------------------------------------- 72 | 73 | CREATE TABLE family (person text PRIMARY KEY, parent text REFERENCES family); 74 | INSERT INTO family VALUES ('Alan', NULL), 75 | ('Bert', 'Alan'), ('Bob', 'Alan'), ('Carl', 'Bert'), ('Carmen', 'Bert'), ('Cecil', 'Bob'), 76 | ('Dave', 'Cecil'), ('Den', 'Cecil'); 77 | 78 | ---------------------------------------------------------------------- 79 | 80 | WITH RECURSIVE genealogy (bloodline, person, level) AS 81 | ( 82 | SELECT person, person, 0 FROM family WHERE person = 'Alan' 83 | UNION ALL 84 | SELECT g.bloodline || ' -> ' || f.person, f.person, g.level + 1 85 | FROM family f, genealogy g WHERE f.parent = g.person 86 | ) 87 | SELECT bloodline, level FROM genealogy; 88 | 89 | ---------------------------------------------------------------------- 90 | 91 | UPDATE family SET parent = 'Bert' WHERE person = 'Alan'; 92 | 93 | WITH RECURSIVE genealogy (bloodline, person, level, processed) AS 94 | ( 95 | SELECT person, person, 0, ARRAY[person] FROM family WHERE person = 'Alan' 96 | UNION ALL 97 | SELECT g.bloodline || ' -> ' || f.person, f.person, g.level + 1, processed || f.person 98 | FROM family f, genealogy g 99 | WHERE f.parent = g.person AND NOT f.person = ANY(processed) 100 | ) 101 | SELECT bloodline, level FROM genealogy; 102 | 103 | ---------------------------------------------------------------------- 104 | 105 | /* 106 | INSERT INTO car_portal_app.car_model (make, model) VALUES ('Ford','Mustang') RETURNING car_model_id; 107 | INSERT INTO car_portal_app.car (number_of_owners, registration_number, manufacture_year, number_of_doors, car_model_id, mileage) 108 | VALUES (1, 'GTR1231', 2014, 4, 100, 10423); 109 | */ 110 | 111 | WITH car_model_insert AS 112 | ( 113 | INSERT INTO car_portal_app.car_model (make, model) VALUES ('Ford','Mustang') 114 | RETURNING car_model_id 115 | ) 116 | INSERT INTO car_portal_app.car (number_of_owners, registration_number, manufacture_year, number_of_doors, car_model_id, mileage) 117 | SELECT 1, 'GTR1231', 2014, 4, car_model_id, 10423 FROM car_model_insert; 118 | 119 | ---------------------------------------------------------------------- 120 | 121 | CREATE TABLE t (f int UNIQUE); 122 | INSERT INTO t VALUES (1); 123 | -- Expected to fail due to unique constraint violation 124 | WITH del_query AS (DELETE FROM t) INSERT INTO t VALUES (1); 125 | 126 | ---------------------------------------------------------------------- 127 | 128 | WITH del_query AS (DELETE FROM t RETURNING f) 129 | INSERT INTO t SELECT 1 WHERE (SELECT count(*) FROM del_query) IS NOT NULL; 130 | 131 | ---------------------------------------------------------------------- 132 | 133 | WITH monthly_data AS ( 134 | SELECT date_trunc('month', advertisement_date) AS month, count(*) as cnt 135 | FROM car_portal_app.advertisement GROUP BY date_trunc('month', advertisement_date) 136 | ) 137 | SELECT to_char(month,'YYYY-MM') as month, cnt, 138 | sum(cnt) OVER (w ORDER BY month) AS cnt_year, 139 | round(avg(cnt) OVER (ORDER BY month ROWS BETWEEN 2 PRECEDING AND 2 FOLLOWING), 1) AS mov_avg, 140 | round(cnt / sum(cnt) OVER w * 100,1) AS ratio_year 141 | FROM monthly_data WINDOW w AS (PARTITION BY date_trunc('year',month)); 142 | 143 | ---------------------------------------------------------------------- 144 | 145 | WITH monthly_data AS ( 146 | SELECT date_trunc('month', advertisement_date) AS month, count(*) as cnt 147 | FROM car_portal_app.advertisement GROUP BY date_trunc('month', advertisement_date) 148 | ) 149 | SELECT to_char(month,'YYYY-MM') as month, cnt, 150 | cnt - lag(cnt) OVER (ORDER BY month) as prev_m, 151 | cnt - lag(cnt, 12) OVER (ORDER BY month) as prev_y, 152 | rank() OVER (w ORDER BY cnt DESC) as rank 153 | FROM monthly_data 154 | WINDOW w AS (PARTITION BY date_trunc('year',month)) 155 | ORDER BY month DESC; 156 | 157 | ---------------------------------------------------------------------- 158 | 159 | SELECT seller_account_id, dense_rank() OVER(ORDER BY count(*) DESC) 160 | FROM car_portal_app.advertisement 161 | GROUP BY seller_account_id; 162 | 163 | ---------------------------------------------------------------------- 164 | 165 | SELECT advertisement_id, advertisement_date, adv.car_id, seller_account_id 166 | FROM car_portal_app.advertisement adv 167 | INNER JOIN 168 | (SELECT car_id, min(advertisement_date) min_date FROM car_portal_app.advertisement GROUP BY car_id) first 169 | ON adv.car_id=first.car_id AND adv.advertisement_date = first.min_date; 170 | 171 | ---------------------------------------------------------------------- 172 | 173 | SELECT DISTINCT first_value(advertisement_id) OVER w AS advertisement_id, 174 | min(advertisement_date) OVER w AS advertisement_date, 175 | car_id, first_value(seller_account_id) OVER w AS seller_account_id 176 | FROM car_portal_app.advertisement 177 | WINDOW w AS (PARTITION BY car_id ORDER BY advertisement_date); 178 | 179 | ---------------------------------------------------------------------- 180 | 181 | SELECT DISTINCT ON (car_id) advertisement_id, advertisement_date, car_id, seller_account_id 182 | FROM car_portal_app.advertisement 183 | ORDER BY car_id, advertisement_date; 184 | 185 | ---------------------------------------------------------------------- 186 | 187 | -- Repeat this 20 times or more depending on the performance of your server 188 | INSERT INTO car_portal_app.advertisement (advertisement_date, car_id, seller_account_id) SELECT advertisement_date, car_id, seller_account_id from car_portal_app.advertisement; 189 | 190 | \timing 191 | SELECT count(*) FROM car_portal_app.advertisement; 192 | SELECT count(*) * 100 FROM car_portal_app.advertisement TABLESAMPLE SYSTEM (1); 193 | SELECT count(*) * 10 from car_portal_app.advertisement TABLESAMPLE SYSTEM (10); 194 | \timing 195 | 196 | ---------------------------------------------------------------------- 197 | 198 | SELECT years.manufacture_year, count(car_id) 199 | FROM generate_series(2010, 2015) as years (manufacture_year) 200 | LEFT JOIN car_portal_app.car ON car.manufacture_year = years.manufacture_year 201 | GROUP BY years.manufacture_year 202 | ORDER BY 1; 203 | 204 | ---------------------------------------------------------------------- 205 | 206 | SELECT * FROM generate_series(5, 11, 3); 207 | 208 | ---------------------------------------------------------------------- 209 | 210 | SELECT * FROM generate_series('2015-01-01'::date, '2015-01-31'::date, interval '7 days'); 211 | 212 | ---------------------------------------------------------------------- 213 | 214 | SELECT foo.a, foo.b FROM ROWS FROM (generate_series(1,3), generate_series(1,7,2)) AS foo(a, b); 215 | 216 | ---------------------------------------------------------------------- 217 | 218 | SELECT car_id, manufacture_year, 219 | CASE WHEN manufacture_year <= ( 220 | SELECT avg(manufacture_year) FROM car_portal_app.car WHERE car_model_id = c.car_model_id) 221 | THEN 'old' ELSE 'new' END as age, 222 | (SELECT count(*) FROM car_portal_app.car WHERE car_model_id = c.car_model_id) AS same_model_count 223 | FROM car_portal_app.car c; 224 | 225 | ---------------------------------------------------------------------- 226 | 227 | SELECT car_id, manufacture_year, 228 | CASE WHEN manufacture_year <= avg_year THEN 'old' ELSE 'new' END as age, 229 | same_model_count 230 | FROM car_portal_app.car 231 | INNER JOIN ( 232 | SELECT car_model_id, avg(manufacture_year) avg_year, count(*) same_model_count 233 | FROM car_portal_app.car GROUP BY car_model_id) subq USING (car_model_id); 234 | 235 | ---------------------------------------------------------------------- 236 | 237 | SELECT car_id, manufacture_year, 238 | CASE WHEN manufacture_year <= avg_year THEN 'old' ELSE 'new' END as age, 239 | same_model_count 240 | FROM car_portal_app.car c, 241 | LATERAL ( 242 | SELECT avg(manufacture_year) avg_year,count(*) same_model_count 243 | FROM car_portal_app.car 244 | WHERE car_model_id = c.car_model_id) subq; 245 | 246 | ---------------------------------------------------------------------- 247 | 248 | SELECT a, b FROM generate_series(1,3) AS a, generate_series(a, a+2) AS b; 249 | 250 | ---------------------------------------------------------------------- 251 | 252 | SELECT to_char(advertisement_date, 'YYYY-Q') as quarter, make, count(*) 253 | FROM car_portal_app.advertisement a 254 | INNER JOIN car_portal_app.car c ON a.car_id = c.car_id 255 | INNER JOIN car_portal_app.car_model m ON m.car_model_id = c.car_model_id 256 | GROUP BY quarter, make; 257 | 258 | ---------------------------------------------------------------------- 259 | 260 | SELECT to_char(advertisement_date, 'YYYY-Q') as quarter, count(*) 261 | FROM car_portal_app.advertisement a 262 | INNER JOIN car_portal_app.car c ON a.car_id = c.car_id 263 | INNER JOIN car_portal_app.car_model m ON m.car_model_id = c.car_model_id 264 | GROUP BY quarter; 265 | 266 | ---------------------------------------------------------------------- 267 | 268 | SELECT count(*) 269 | FROM car_portal_app.advertisement a 270 | INNER JOIN car_portal_app.car c ON a.car_id = c.car_id 271 | INNER JOIN car_portal_app.car_model m ON m.car_model_id = c.car_model_id; 272 | 273 | ---------------------------------------------------------------------- 274 | 275 | SELECT to_char(advertisement_date, 'YYYY-Q') as quarter, make, count(*) 276 | FROM car_portal_app.advertisement a 277 | INNER JOIN car_portal_app.car c ON a.car_id = c.car_id 278 | INNER JOIN car_portal_app.car_model m ON m.car_model_id = c.car_model_id 279 | GROUP BY GROUPING SETS ((quarter, make), (quarter), ()) 280 | ORDER BY quarter NULLS LAST, make NULLS LAST; 281 | 282 | ---------------------------------------------------------------------- 283 | 284 | SELECT percentile_disc(ARRAY[0.25, 0.5, 0.75]) WITHIN GROUP (ORDER BY cnt) 285 | FROM (SELECT count(*) cnt FROM car_portal_app.advertisement GROUP BY car_id) subq; 286 | 287 | ---------------------------------------------------------------------- 288 | 289 | SELECT mode() WITHIN GROUP (ORDER BY car_model_id) FROM car_portal_app.car; 290 | 291 | ---------------------------------------------------------------------- 292 | 293 | SELECT rank(2) WITHIN GROUP (ORDER BY a) FROM generate_series(1,10,3) a; 294 | 295 | ---------------------------------------------------------------------- 296 | 297 | SELECT car_model_id, number_of_doors, count(*) 298 | FROM car_portal_app.car 299 | GROUP BY car_model_id, number_of_doors; 300 | 301 | ---------------------------------------------------------------------- 302 | 303 | SELECT car_model_id, 304 | count(CASE WHEN number_of_doors = 2 THEN 1 END) doors2, 305 | count(CASE WHEN number_of_doors = 3 THEN 1 END) doors3, 306 | count(CASE WHEN number_of_doors = 4 THEN 1 END) doors4, 307 | count(CASE WHEN number_of_doors = 5 THEN 1 END) doors5 308 | FROM car_portal_app.car 309 | GROUP BY car_model_id, number_of_doors; 310 | 311 | ---------------------------------------------------------------------- 312 | 313 | SELECT car_model_id, 314 | count(*) FILTER (WHERE number_of_doors = 2) doors2, 315 | count(*) FILTER (WHERE number_of_doors = 3) doors3, 316 | count(*) FILTER (WHERE number_of_doors = 4) doors4, 317 | count(*) FILTER (WHERE number_of_doors = 5) doors5 318 | FROM car_portal_app.car GROUP BY car_model_id; 319 | 320 | ---------------------------------------------------------------------- 321 | 322 | 323 | -------------------------------------------------------------------------------- /Chapter07/plpgsql.sql: -------------------------------------------------------------------------------- 1 | -- Function vs procedure 2 | CREATE PROCEDURE test_procedure_tx() AS $$ 3 | BEGIN 4 | CREATE TABLE a (id int); 5 | COMMIT; 6 | CREATE INDEX a_id_idx ON a(id); 7 | SELECT 1/0; 8 | END; 9 | $$ LANGUAGE plpgsql ; 10 | 11 | CREATE FUNCTION test_function_tx() RETURNS VOID AS $$ 12 | BEGIN 13 | CREATE TABLE a (id int); 14 | CREATE INDEX a_id_idx ON a(id); 15 | SELECT 1/0; 16 | END; 17 | $$ LANGUAGE plpgsql ; 18 | SELECT test_function_tx(); 19 | call test_procedure_tx(); 20 | 21 | --- Parameters, security 22 | 23 | -- Enable all users to access database via socket. 24 | # Database administrative login by Unix domain socket 25 | --local all all trust 26 | 27 | CREATE FUNCTION test_security_definer () RETURNS TEXT AS $$ 28 | SELECT format ('current_user:%s session_user:%s', current_user, session_user); 29 | $$ LANGUAGE SQL SECURITY DEFINER; 30 | 31 | CREATE FUNCTION test_security_invoker () RETURNS TEXT AS $$ 32 | SELECT format ('current_user:%s session_user:%s', current_user, session_user); 33 | $$ LANGUAGE SQL SECURITY INVOKER; 34 | 35 | psql -U postgres car_portal 36 | SELECT test_security_definer() , test_security_invoker(); 37 | psql -U car_portal_app car_portal 38 | SELECT test_security_definer() , test_security_invoker(); 39 | 40 | --- Paramter, row 41 | CREATE OR REPLACE FUNCTION a() RETURNS SET OF INTEGER AS $$ 42 | SELECT 1; 43 | $$ LANGUAGE SQL; 44 | EXPLAIN SELECT * FROM a() CROSS JOIN (Values(1),(2),(3)) as foo; 45 | 46 | --- Paramter, cost 47 | CREATE OR REPLACE FUNCTION slow_function (anyelement) RETURNS BOOLEAN AS $$ 48 | BEGIN 49 | RAISE NOTICE 'Slow function %', $1; 50 | RETURN TRUE; 51 | END; $$ LANGUAGE PLPGSQL COST 10000; 52 | 53 | CREATE OR REPLACE FUNCTION fast_function (anyelement) RETURNS BOOLEAN AS $$ 54 | BEGIN 55 | RAISE NOTICE 'Fast function %', $1; 56 | RETURN TRUE; 57 | END; $$ LANGUAGE PLPGSQL COST 0.0001; 58 | 59 | EXPLAIN SELECT * FROM pg_language WHERE fast_function(lanname) AND slow_function(lanname) AND lanname ILIKE '%sql%'; 60 | EXPLAIN SELECT * FROM pg_language WHERE slow_function(lanname) AND fast_function(lanname) AND lanname ILIKE '%sql%'; 61 | SELECT lanname FROM pg_language WHERE lanname ILIKE '%sql%' AND slow_function(lanname)AND fast_function(lanname); 62 | 63 | CREATE OR REPLACE VIEW pg_sql_pl AS SELECT lanname FROM pg_language WHERE lanname ILIKE '%sql%'; 64 | ALTER FUNCTION fast_function(anyelement) LEAKPROOF; 65 | SELECT * FROM pg_sql_pl WHERE fast_function(lanname); 66 | 67 | --- paramter , planner 68 | EXPLAIN (analyze, buffers) SELECT md5(random()::text) FROM generate_series(1, 1000000) order by 1; 69 | 70 | CREATE OR REPLACE FUNCTION configuration_test () RETURNS TABLE(md5 text) AS $$ 71 | SELECT md5(random()::text) FROM generate_series(1, 1000000) order by 1; 72 | $$ LANGUAGE SQL 73 | SET enable_seqscan FROM current 74 | SET work_mem = '100MB'; 75 | 76 | --- 77 | 78 | CREATE OR REPLACE FUNCTION factorial(INTEGER ) RETURNS INTEGER AS $$ 79 | BEGIN 80 | IF $1 IS NULL OR $1 < 0 THEN RAISE NOTICE 'Invalid Number'; 81 | RETURN NULL; 82 | ELSIF $1 = 1 THEN 83 | RETURN 1; 84 | ELSE 85 | RETURN factorial($1 - 1) * $1; 86 | END IF; 87 | END; 88 | $$ LANGUAGE 'plpgsql'; 89 | 90 | CREATE OR REPLACE FUNCTION factorial(INTEGER ) RETURNS INTEGER AS $$ 91 | DECLARE 92 | fact ALIAS FOR $1; 93 | BEGIN 94 | IF fact IS NULL OR fact < 0 THEN 95 | RAISE NOTICE 'Invalid Number'; 96 | RETURN NULL; 97 | ELSIF fact = 1 THEN 98 | RETURN 1; 99 | END IF; 100 | DECLARE 101 | result INT; 102 | BEGIN 103 | result = factorial(fact - 1) * fact; 104 | RETURN result; 105 | END; 106 | END; 107 | $$ LANGUAGE 'plpgsql' 108 | 109 | 110 | CREATE OR REPLACE FUNCTION cast_numeric_to_int (numeric_value numeric, round boolean = TRUE /*correct use of "=". Using ":=" will raise a syntax error */) 111 | RETURNS INT AS 112 | $$ 113 | BEGIN 114 | RETURN (CASE WHEN round = TRUE THEN CAST (numeric_value AS INTEGER) 115 | WHEN numeric_value>= 0 THEN CAST (numeric_value -.5 AS INTEGER) 116 | WHEN numeric_value< 0 THEN CAST (numeric_value +.5 AS INTEGER) 117 | ELSE NULL 118 | END); 119 | END; 120 | $$ LANGUAGE plpgsql; 121 | 122 | SELECT cast_numeric_to_int(2.3, round:= true); 123 | 124 | SELECT cast_numeric_to_int(2.3, round= true); 125 | 126 | DO $$ 127 | DECLARE 128 | test record; 129 | BEGIN 130 | test = ROW (1,'hello', 3.14); 131 | RAISE notice '%', test; 132 | END; 133 | $$ LANGUAGE plpgsql; 134 | 135 | 136 | DO $$ 137 | DECLARE 138 | number_of_accounts INT:=0; 139 | BEGIN 140 | number_of_accounts:= (SELECT COUNT(*) FROM car_portal_app.account)::INT; 141 | RAISE NOTICE 'number_of accounts: %', number_of_accounts; 142 | END;$$ 143 | LANGUAGE plpgsql; 144 | 145 | CREATE TABLE test ( 146 | id SERIAL PRIMARY KEY, 147 | name TEXT NOT NULL 148 | ); 149 | 150 | 151 | DO $$ 152 | DECLARE 153 | auto_generated_id INT; 154 | BEGIN 155 | INSERT INTO test(name) VALUES ('Hello World') RETURNING id INTO auto_generated_id; 156 | RAISE NOTICE 'The primary key is: %', auto_generated_id; 157 | END 158 | $$; 159 | 160 | CREATE OR REPLACE FUNCTION cast_rank_to_text (rank int) RETURNS TEXT AS $$ 161 | DECLARE 162 | rank ALIAS FOR $1; 163 | rank_result TEXT; 164 | BEGIN 165 | IF rank = 5 THEN rank_result = 'Excellent'; 166 | ELSIF rank = 4 THEN rank_result = 'Very Good'; 167 | ELSIF rank = 3 THEN rank_result = 'Good'; 168 | ELSIF rank = 2 THEN rank_result ='Fair'; 169 | ELSIF rank = 1 THEN rank_result ='Poor'; 170 | ELSE rank_result ='No such rank'; 171 | END IF; 172 | RETURN rank_result; 173 | END; 174 | $$ Language plpgsql; 175 | 176 | 177 | CREATE OR REPLACE FUNCTION cast_rank_to_text (rank int) RETURNS TEXT AS $$ 178 | DECLARE 179 | rank ALIAS FOR $1; 180 | rank_result TEXT; 181 | BEGIN 182 | CASE rank 183 | WHEN 5 THEN rank_result = 'Excellent'; 184 | WHEN 4 THEN rank_result = 'Very Good'; 185 | WHEN 3 THEN rank_result = 'Good'; 186 | WHEN 2 THEN rank_result ='Fair'; 187 | WHEN 1 THEN rank_result ='Poor'; 188 | ELSE rank_result ='No such rank'; 189 | END CASE; 190 | RETURN rank_result; 191 | END;$$ Language plpgsql; 192 | 193 | 194 | CREATE OR REPLACE FUNCTION cast_rank_to_text (rank int) RETURNS TEXT AS $$ 195 | DECLARE 196 | rank ALIAS FOR $1; 197 | rank_result TEXT; 198 | BEGIN 199 | CASE 200 | WHEN rank=5 THEN rank_result = 'Excellent'; 201 | WHEN rank=4 THEN rank_result = 'Very Good'; 202 | WHEN rank=3 THEN rank_result = 'Good'; 203 | WHEN rank=2 THEN rank_result ='Fair'; 204 | WHEN rank=1 THEN rank_result ='Poor'; 205 | WHEN rank IS NULL THEN RAISE EXCEPTION 'Rank should be not NULL'; 206 | ELSE rank_result ='No such rank'; 207 | END CASE; 208 | RETURN rank_result; 209 | END; 210 | $$ Language plpgsql; 211 | --- to test 212 | SELECT cast_rank_to_text(null); 213 | 214 | DO $$ 215 | DECLARE 216 | i int := 0; 217 | BEGIN 218 | case WHEN i=1 then 219 | RAISE NOTICE 'i is one'; 220 | END CASE; 221 | END; 222 | $$ LANGUAGE plpgsql; 223 | 224 | 225 | CREATE OR REPLACE FUNCTION factorial (fact int) RETURNS BIGINT AS $$ 226 | DECLARE 227 | result bigint = 1; 228 | BEGIN 229 | IF fact = 1 THEN RETURN 1; 230 | ELSIF fact IS NULL or fact < 1 THEN RAISE EXCEPTION 'Provide a positive integer'; 231 | ELSE 232 | LOOP 233 | result = result*fact; 234 | fact = fact-1; 235 | EXIT WHEN fact = 1; 236 | END Loop; 237 | END IF; 238 | RETURN result; 239 | END; $$ LANGUAGE plpgsql; 240 | 241 | DO $$ 242 | DECLARE 243 | first_day_in_month date := date_trunc('month', current_date)::date; 244 | last_day_in_month date := (date_trunc('month', current_date)+ INTERVAL '1 MONTH - 1 day')::date; 245 | counter date = first_day_in_month; 246 | BEGIN 247 | WHILE (counter <= last_day_in_month) LOOP 248 | RAISE notice '%', counter; 249 | counter := counter + interval '1 day'; 250 | END LOOP; 251 | END; 252 | $$ LANGUAGE plpgsql; 253 | 254 | 255 | DO $$ 256 | BEGIN 257 | FOR j IN REVERSE -1 .. -10 BY 2 LOOP 258 | Raise notice '%', j; 259 | END LOOP; 260 | END; $$ LANGUAGE plpgsql; 261 | 262 | DO $$ 263 | DECLARE 264 | table_name text; 265 | BEGIN 266 | FOR table_name IN SELECT tablename FROM pg_tables WHERE schemaname ='car_portal_app' LOOP 267 | RAISE NOTICE 'Analyzing %', table_name; 268 | EXECUTE 'ANALYZE car_portal_app.' || table_name; 269 | END LOOP; 270 | END; 271 | $$; 272 | 273 | DO $$ 274 | DECLARE 275 | database RECORD; 276 | BEGIN 277 | FOR database IN SELECT * FROM pg_database LOOP 278 | RAISE notice '%', database.datname; 279 | END LOOP; 280 | END; $$; 281 | 282 | DO $$ 283 | BEGIN 284 | RETURN; 285 | RAISE NOTICE 'This statement will not be executed'; 286 | END 287 | $$ 288 | LANGUAGE plpgsql; 289 | -- in sql 290 | CREATE OR REPLACE FUNCTION car_portal_app.get_account_in_json (account_id INT) RETURNS JSON AS $$ 291 | SELECT row_to_json(account) FROM car_portal_app.account WHERE account_id = $1; 292 | $$ LANGUAGE SQL; 293 | 294 | --- in plpgsql 295 | CREATE OR REPLACE FUNCTION car_portal_app.get_account_in_json1 (acc_id INT) RETURNS JSON AS $$ 296 | BEGIN 297 | RETURN (SELECT row_to_json(account) FROM car_portal_app.account WHERE account_id = acc_id); 298 | END; 299 | $$ LANGUAGE plpgsql; 300 | 301 | -- In SQL 302 | CREATE OR REPLACE FUNCTION car_portal_app.car_model(model_name TEXT) RETURNS SETOF car_portal_app.car_model AS $$ 303 | SELECT car_model_id, make, model FROM car_portal_app.car_model WHERE model = model_name; 304 | $$ LANGUAGE SQL; 305 | 306 | -- In plpgSQL 307 | CREATE OR REPLACE FUNCTION car_portal_app.car_model1(model_name TEXT) RETURNS SETOF car_portal_app.car_model AS $$ 308 | BEGIN 309 | RETURN QUERY SELECT car_model_id, make, model FROM car_portal_app.car_model WHERE model = model_name; 310 | END; 311 | $$ LANGUAGE plpgsql; 312 | 313 | -- SQL 314 | CREATE OR REPLACE FUNCTION car_portal_app.car_model2(model_name TEXT) RETURNS TABLE (car_model_id INT , make TEXT) AS $$ 315 | SELECT car_model_id, make FROM car_portal_app.car_model WHERE model = model_name; 316 | $$ LANGUAGE SQL; 317 | 318 | -- plpgSQL 319 | CREATE OR REPLACE FUNCTION car_portal_app.car_model3(model_name TEXT) RETURNS TABLE (car_model_id INT , make TEXT) AS $$ 320 | BEGIN 321 | RETURN QUERY SELECT car_model_id, make FROM car_portal_app.car_model WHERE model = model_name; 322 | END; 323 | $$ LANGUAGE plpgsql; 324 | 325 | 326 | CREATE OR REPLACE FUNCTION car_portal_app.car_model3(model_name TEXT) RETURNS TABLE (car_model_id INT , make TEXT) AS $$ 327 | BEGIN 328 | RETURN QUERY SELECT a.car_model_id, a.make FROM car_portal_app.car_model a WHERE model = model_name; 329 | END; 330 | $$ LANGUAGE plpgsql; 331 | SELECT * FROM car_portal_app.car_model3('A1'); 332 | 333 | CREATE OR REPLACE FUNCTION car_portal_app.car_model4(model_name TEXT, OUT car_model_id INT, OUT make TEXT ) RETURNS SETOF RECORD AS $$ 334 | BEGIN 335 | RETURN QUERY SELECT a.car_model_id, a.make FROM car_portal_app.car_model a WHERE model = model_name; 336 | END; 337 | $$ LANGUAGE plpgsql; 338 | SELECT * FROM car_portal_app.car_model4('A1'::text); 339 | 340 | DO $$ 341 | BEGIN 342 | CREATE TABLE t1(f1 int); 343 | 344 | INSERT INTO t1 VALUES (1); 345 | RAISE NOTICE '%', FOUND; 346 | 347 | PERFORM* FROM t1 WHERE f1 = 0; 348 | RAISE NOTICE '%', FOUND; 349 | DROP TABLE t1; 350 | END; 351 | $$LANGUAGE plpgsql; 352 | 353 | CREATE OR REPLACE FUNCTION check_not_null (value anyelement ) RETURNS VOID AS 354 | $$ 355 | BEGIN 356 | IF (value IS NULL) THEN RAISE EXCEPTION USING ERRCODE = 'check_violation'; END IF; 357 | END; 358 | $$ LANGUAGE plpgsql; 359 | 360 | 361 | DO $$ 362 | BEGIN 363 | RAISE EXCEPTION USING ERRCODE = '1234X', MESSAGE = 'test customized SQLSTATE:'; 364 | EXCEPTION WHEN SQLSTATE '1234X' THEN 365 | RAISE NOTICE '% %', SQLERRM, SQLSTATE; 366 | END; 367 | $$ LANGUAGE plpgsql; 368 | 369 | DROP FUNCTION IF EXISTS factorial( INTEGER ); 370 | CREATE OR REPLACE FUNCTION factorial(INTEGER ) RETURNS BIGINT AS $$ 371 | DECLARE 372 | fact ALIAS FOR $1; 373 | BEGIN 374 | PERFORM check_not_null(fact); 375 | IF fact > 1 THEN RETURN factorial(fact - 1) * fact; 376 | ELSIF fact IN (0,1) THEN RETURN 1; 377 | ELSE RETURN NULL; 378 | END IF; 379 | 380 | EXCEPTION 381 | WHEN check_violation THEN RETURN NULL; 382 | WHEN OTHERS THEN RAISE NOTICE '% %', SQLERRM, SQLSTATE; 383 | END; 384 | $$ LANGUAGE 'plpgsql'; 385 | 386 | CREATE OR REPLACE FUNCTION car_portal_app.get_account (predicate TEXT) RETURNS SETOF car_portal_app.account AS 387 | $$ 388 | BEGIN 389 | RETURN QUERY EXECUTE 'SELECT * FROM car_portal_app.account WHERE ' || predicate; 390 | END; 391 | $$ LANGUAGE plpgsql; 392 | SELECT * FROM car_portal_app.get_account ('true') limit 1; 393 | SELECT * FROM car_portal_app.get_account (E'first_name=\'James\''); 394 | 395 | CREATE OR REPLACE FUNCTION car_portal_app.get_advertisement_count (some_date timestamptz ) RETURNS BIGINT AS $$ 396 | BEGIN 397 | RETURN (SELECT count (*) FROM car_portal_app.advertisement WHERE advertisement_date >=some_date)::bigint; 398 | END; 399 | $$ LANGUAGE plpgsql; 400 | 401 | CREATE OR REPLACE FUNCTION car_portal_app.get_advertisement_count (some_date timestamptz ) RETURNS BIGINT AS $$ 402 | DECLARE 403 | count BIGINT; 404 | BEGIN 405 | EXECUTE 'SELECT count (*) FROM car_portal_app.advertisement WHERE advertisement_date >= $1' USING some_date INTO count; 406 | RETURN count; 407 | END; 408 | $$ LANGUAGE plpgsql; 409 | 410 | CREATE OR REPLACE FUNCTION car_portal_app.can_login (email text, pass text) RETURNS BOOLEAN AS $$ 411 | DECLARE 412 | stmt TEXT; 413 | result bool; 414 | BEGIN 415 | stmt = E'SELECT COALESCE (count(*)=1, false) FROM car_portal_app.account WHERE email = \''|| $1 || E'\' and password = \''||$2||E'\''; 416 | RAISE NOTICE '%' , stmt; 417 | EXECUTE stmt INTO result; 418 | RETURN result; 419 | END; 420 | $$ LANGUAGE plpgsql; 421 | 422 | SELECT car_portal_app.can_login('jbutt@gmail.com', md5('jbutt@gmail.com')); 423 | SELECT car_portal_app.can_login('jbutt@gmail.com', md5('jbutt@yahoo.com')); 424 | SELECT car_portal_app.can_login(E'jbutt@gmail.com\'--', 'Do not know password'); 425 | 426 | CREATE OR REPLACE FUNCTION car_portal_app.can_login (email text, pass text) RETURNS BOOLEAN AS 427 | $$ 428 | DECLARE 429 | stmt TEXT; 430 | result bool; 431 | BEGIN 432 | stmt = format('SELECT COALESCE (count(*)=1, false) FROM car_portal_app.account WHERE email = %Land password = %L', $1,$2); 433 | RAISE NOTICE '%' , stmt; 434 | EXECUTE stmt INTO result; 435 | RETURN result; 436 | END; 437 | $$ LANGUAGE plpgsql; -------------------------------------------------------------------------------- /Chapter05/SQL Language/examples.sql: -------------------------------------------------------------------------------- 1 | SELECT car_id, number_of_doors FROM car_portal_app.car; 2 | 3 | ---------------------------------------------------------------------- 4 | 5 | BEGIN; 6 | 7 | DELETE FROM car_portal_app.a; 8 | 9 | ROLLBACK; 10 | 11 | ---------------------------------------------------------------------- 12 | 13 | SELECT now(); 14 | 15 | ---------------------------------------------------------------------- 16 | 17 | SELECT 1, 1.2, 0.3, .5, 1e15, 12.65e-6; 18 | 19 | ---------------------------------------------------------------------- 20 | 21 | SELECT 'a', 'aa''aa', E'aa\naa', $$aa'aa$$, U&'\041C\0418\0420'; 22 | 23 | ---------------------------------------------------------------------- 24 | 25 | SELECT $str1$SELECT $$dollar-quoted string$$;$str1$; 26 | 27 | ---------------------------------------------------------------------- 28 | 29 | SELECT B'01010101'::int, X'AB21'::int; 30 | 31 | ---------------------------------------------------------------------- 32 | 33 | SELECT car_id, registration_number, manufacture_year 34 | FROM car_portal_app.car 35 | WHERE number_of_doors=3 36 | ORDER BY car_id 37 | LIMIT 5; 38 | 39 | ---------------------------------------------------------------------- 40 | 41 | SELECT * FROM car_portal_app.car; 42 | 43 | ---------------------------------------------------------------------- 44 | 45 | SELECT 1; 46 | 47 | ---------------------------------------------------------------------- 48 | 49 | SELECT car.car_id, car.number_of_owners FROM car_portal_app.car; 50 | 51 | ---------------------------------------------------------------------- 52 | 53 | SELECT 1+1 AS two, 13%4 AS one, -5 AS minus_five, 5! AS factorial, |/25 AS square_root ; 54 | 55 | ---------------------------------------------------------------------- 56 | 57 | SELECT substring('this is a string constant',11,6); 58 | 59 | ---------------------------------------------------------------------- 60 | 61 | SELECT (SELECT 1) + (SELECT 2) AS three; 62 | 63 | ---------------------------------------------------------------------- 64 | 65 | SELECT 'One plus one equals ' || (1+1) AS str; 66 | 67 | ---------------------------------------------------------------------- 68 | 69 | SELECT CASE WHEN now() > date_trunc('day', now()) + interval '12 hours' 70 | THEN 'PM' ELSE 'AM' END; 71 | 72 | ---------------------------------------------------------------------- 73 | 74 | SELECT ALL make FROM car_portal_app.car_model; 75 | 76 | ---------------------------------------------------------------------- 77 | 78 | SELECT DISTINCT make FROM car_portal_app.car_model; 79 | 80 | ---------------------------------------------------------------------- 81 | 82 | SELECT DISTINCT substring(make, 1, 1) FROM car_portal_app.car_model; 83 | 84 | ---------------------------------------------------------------------- 85 | 86 | SELECT a.car_id, a.number_of_doors FROM car_portal_app.car AS a; 87 | 88 | ---------------------------------------------------------------------- 89 | 90 | SELECT * FROM car_portal_app.a; 91 | 92 | ---------------------------------------------------------------------- 93 | 94 | SELECT * FROM car_portal_app.b; 95 | 96 | ---------------------------------------------------------------------- 97 | 98 | SELECT * FROM car_portal_app.a, car_portal_app.b; 99 | 100 | ---------------------------------------------------------------------- 101 | 102 | SELECT * FROM car_portal_app.a, car_portal_app.b WHERE a_int=b_int; 103 | 104 | ---------------------------------------------------------------------- 105 | 106 | SELECT * FROM car_portal_app.a JOIN car_portal_app.b ON a_int=b_int; 107 | 108 | ---------------------------------------------------------------------- 109 | 110 | SELECT * FROM car_portal_app.a JOIN car_portal_app.b ON a_int=b_int; 111 | 112 | ---------------------------------------------------------------------- 113 | 114 | SELECT * FROM car_portal_app.a LEFT JOIN car_portal_app.b ON a_int=b_int; 115 | 116 | ---------------------------------------------------------------------- 117 | 118 | SELECT * FROM car_portal_app.a RIGHT JOIN car_portal_app.b ON a_int=b_int; 119 | 120 | ---------------------------------------------------------------------- 121 | 122 | SELECT * FROM car_portal_app.a FULL JOIN car_portal_app.b ON a_int=b_int; 123 | 124 | ---------------------------------------------------------------------- 125 | 126 | SELECT * 127 | FROM car_portal_app.a 128 | INNER JOIN 129 | (SELECT * FROM car_portal_app.b WHERE b_text = 'two') subq 130 | ON a.a_int=subq.b_int; 131 | 132 | ---------------------------------------------------------------------- 133 | 134 | SELECT * FROM car_portal_app.a CROSS JOIN car_portal_app.b; 135 | 136 | ---------------------------------------------------------------------- 137 | 138 | SELECT * FROM car_portal_app.a, car_portal_app.b; 139 | 140 | ---------------------------------------------------------------------- 141 | 142 | SELECT * FROM car_portal_app.a INNER JOIN car_portal_app.b ON a.a_int=b.b_int; 143 | 144 | ---------------------------------------------------------------------- 145 | 146 | SELECT * FROM car_portal_app.a, car_portal_app.b WHERE a.a_int=b.b_int; 147 | 148 | ---------------------------------------------------------------------- 149 | 150 | SELECT t1.a_int AS current, t2.a_int AS bigger 151 | FROM car_portal_app.a t1 152 | INNER JOIN car_portal_app.a t2 ON t2.a_int > t1.a_int; 153 | 154 | ---------------------------------------------------------------------- 155 | 156 | SELECT t1.a_int AS current, t2.a_int AS bigger 157 | FROM car_portal_app.a t1 158 | LEFT JOIN car_portal_app.a t2 ON t2.a_int > t1.a_int; 159 | 160 | ---------------------------------------------------------------------- 161 | 162 | SELECT * FROM car_portal_app.car_model WHERE make='Peugeot'; 163 | 164 | ---------------------------------------------------------------------- 165 | 166 | SELECT * FROM car_portal_app.car WHERE mileage < 25000; 167 | 168 | ---------------------------------------------------------------------- 169 | 170 | SELECT * FROM car_portal_app.car WHERE number_of_doors > 3 AND number_of_owners <= 2; 171 | 172 | ---------------------------------------------------------------------- 173 | 174 | SELECT * FROM car_portal_app.car_model WHERE length(model)=4; 175 | 176 | ---------------------------------------------------------------------- 177 | 178 | SELECT 1 WHERE (date '2018-10-15', date '2018-10-31') 179 | OVERLAPS (date '2018-10-25', date '2018-11-15'); 180 | 181 | ---------------------------------------------------------------------- 182 | 183 | SELECT * FROM car_portal_app.car_model WHERE model ILIKE 's___'; 184 | 185 | ---------------------------------------------------------------------- 186 | 187 | SELECT * FROM car_portal_app.car_model WHERE model ~ '^\w+\W+\w+$'; 188 | 189 | ---------------------------------------------------------------------- 190 | 191 | SELECT * FROM car_portal_app.car_model 192 | WHERE car_model_id IN (SELECT car_model_id FROM car_portal_app.car); 193 | 194 | ---------------------------------------------------------------------- 195 | 196 | SELECT car_model.* 197 | FROM car_portal_app.car_model INNER JOIN car_portal_app.car USING (car_model_id); 198 | 199 | ---------------------------------------------------------------------- 200 | 201 | SELECT make, model 202 | FROM car_portal_app.car a 203 | INNER JOIN car_portal_app.car_model b ON a.car_model_id=b.car_model_id 204 | GROUP BY make, model; 205 | 206 | ---------------------------------------------------------------------- 207 | 208 | SELECT make, model, count(*) 209 | FROM car_portal_app.car a 210 | INNER JOIN car_portal_app.car_model b ON a.car_model_id=b.car_model_id 211 | GROUP BY make, model; 212 | 213 | ---------------------------------------------------------------------- 214 | 215 | SELECT a_int, a_text FROM car_portal_app.a GROUP BY a_int; 216 | 217 | ---------------------------------------------------------------------- 218 | 219 | SELECT count(*) FROM car_portal_app.car; 220 | 221 | ---------------------------------------------------------------------- 222 | 223 | SELECT count(*) FROM car_portal_app.car WHERE number_of_doors = 15; 224 | 225 | ---------------------------------------------------------------------- 226 | 227 | SELECT count(*), count(DISTINCT car_model_id) FROM car_portal_app.car; 228 | 229 | ---------------------------------------------------------------------- 230 | 231 | SELECT make, model FROM 232 | ( 233 | SELECT make, model, count(*) c 234 | FROM car_portal_app.car a 235 | INNER JOIN car_portal_app.car_model b ON a.car_model_id=b.car_model_id 236 | GROUP BY make, model 237 | ) subq 238 | WHERE c > 5; 239 | 240 | ---------------------------------------------------------------------- 241 | 242 | SELECT a.make, a.model 243 | FROM car_portal_app.car_model a 244 | INNER JOIN car_portal_app.car b ON a.car_model_id=b.car_model_id 245 | GROUP BY a.make, a.model 246 | HAVING count(*)>5; 247 | 248 | ---------------------------------------------------------------------- 249 | 250 | SELECT number_of_owners, manufacture_year, trunc(mileage/1000) as kmiles 251 | FROM car_portal_app.car 252 | ORDER BY number_of_owners, manufacture_year, trunc(mileage/1000) DESC; 253 | 254 | ---------------------------------------------------------------------- 255 | 256 | SELECT number_of_owners, manufacture_year, trunc(mileage/1000) as kmiles 257 | FROM car_portal_app.car 258 | ORDER BY number_of_owners, manufacture_year, kmiles DESC; 259 | 260 | ---------------------------------------------------------------------- 261 | 262 | SELECT number_of_owners, manufacture_year, trunc(mileage/1000) as kmiles 263 | FROM car_portal_app.car 264 | ORDER BY 1, 2, 3 DESC; 265 | 266 | ---------------------------------------------------------------------- 267 | 268 | SELECT * FROM car_portal_app.car_model LIMIT 5; 269 | 270 | ---------------------------------------------------------------------- 271 | 272 | SELECT * FROM car_portal_app.car_model OFFSET 5 LIMIT 5; 273 | 274 | ---------------------------------------------------------------------- 275 | 276 | SELECT * FROM 277 | (SELECT car_model_id, count(*) c FROM car_portal_app.car GROUP BY car_model_id) subq 278 | WHERE c = 1; 279 | 280 | ---------------------------------------------------------------------- 281 | 282 | SELECT car_id, registration_number 283 | FROM car_portal_app.car 284 | WHERE car_model_id IN (SELECT car_model_id FROM car_portal_app.car_model WHERE make='Peugeot'); 285 | 286 | ---------------------------------------------------------------------- 287 | 288 | SELECT (SELECT count(*) FROM car_portal_app.car_model) 289 | FROM car_portal_app.car 290 | LIMIT (SELECT MIN(car_id)+2 FROM car_portal_app.car); 291 | 292 | ---------------------------------------------------------------------- 293 | 294 | SELECT make, model, 295 | (SELECT count(*) FROM car_portal_app.car WHERE car_model_id = main.car_model_id) 296 | FROM car_portal_app.car_model main 297 | ORDER BY 3 DESC 298 | LIMIT 5; 299 | 300 | ---------------------------------------------------------------------- 301 | 302 | SELECT 'a', * FROM 303 | ( 304 | SELECT * FROM car_portal_app.a 305 | EXCEPT ALL 306 | SELECT * FROM car_portal_app.b 307 | ) v1 308 | UNION ALL 309 | SELECT 'b', * FROM 310 | ( 311 | SELECT * FROM car_portal_app.b 312 | EXCEPT ALL 313 | SELECT * FROM car_portal_app.a 314 | ) v2; 315 | 316 | ---------------------------------------------------------------------- 317 | 318 | SELECT true AND NULL, false AND NULL, true OR NULL, false OR NULL, NOT NULL; 319 | 320 | ---------------------------------------------------------------------- 321 | 322 | SELECT 1 IN (1, NULL) as in; 323 | 324 | ---------------------------------------------------------------------- 325 | 326 | SELECT 2 IN (1, NULL) as in; 327 | 328 | ---------------------------------------------------------------------- 329 | 330 | SELECT a IS NULL, b IS NULL, a = b FROM (SELECT ''::text a, NULL::text b) v; 331 | 332 | ---------------------------------------------------------------------- 333 | 334 | INSERT INTO car_portal_app.a (a_int) VALUES (6); 335 | 336 | ---------------------------------------------------------------------- 337 | 338 | INSERT INTO car_portal_app.a (a_text) VALUES (default); 339 | 340 | ---------------------------------------------------------------------- 341 | 342 | INSERT INTO car_portal_app.a DEFAULT VALUES; 343 | 344 | ---------------------------------------------------------------------- 345 | 346 | INSERT INTO car_portal_app.a (a_int, a_text) VALUES (7, 'seven'), (8, 'eight'); 347 | 348 | ---------------------------------------------------------------------- 349 | 350 | SELECT * FROM (VALUES (7, 'seven'), (8, 'eight')) v; 351 | 352 | ---------------------------------------------------------------------- 353 | 354 | INSERT INTO car_portal_app.a SELECT * FROM car_portal_app.b; 355 | 356 | ---------------------------------------------------------------------- 357 | 358 | INSERT INTO car_portal_app.a SELECT * FROM car_portal_app.b RETURNING a_int; 359 | 360 | 361 | ---------------------------------------------------------------------- 362 | 363 | INSERT INTO car_portal_app.b VALUES (2, 'new_two'); 364 | 365 | ---------------------------------------------------------------------- 366 | 367 | INSERT INTO car_portal_app.b VALUES (2, 'new_two') 368 | ON CONFLICT (b_int) DO UPDATE SET b_text = excluded.b_text 369 | RETURNING *; 370 | 371 | ---------------------------------------------------------------------- 372 | 373 | UPDATE car_portal_app.a u SET a_text = 374 | (SELECT b_text FROM car_portal_app.b WHERE b_int = u.a_int); 375 | 376 | ---------------------------------------------------------------------- 377 | 378 | UPDATE car_portal_app.a SET a_int = b_int FROM car_portal_app.b WHERE a.a_text=b.b_text; 379 | 380 | ---------------------------------------------------------------------- 381 | 382 | UPDATE car_portal_app.a SET a_int = (SELECT b_int FROM car_portal_app.b WHERE a.a_text=b.b_text) 383 | WHERE a_text IN (SELECT b_text FROM car_portal_app.b); 384 | 385 | ---------------------------------------------------------------------- 386 | 387 | UPDATE car_portal_app.a SET a_int = b_int FROM car_portal_app.b; 388 | 389 | ---------------------------------------------------------------------- 390 | 391 | UPDATE car_portal_app.a SET a_int = b_int FROM car_portal_app.b WHERE b_int>=a_int; 392 | 393 | ---------------------------------------------------------------------- 394 | 395 | UPDATE car_portal_app.a SET a_int = 0 RETURNING *; 396 | 397 | ---------------------------------------------------------------------- 398 | 399 | DELETE FROM car_portal_app.a USING car_portal_app.b WHERE a.a_int=b.b_int; 400 | 401 | ---------------------------------------------------------------------- 402 | 403 | DELETE FROM car_portal_app.a 404 | WHERE a_int IN (SELECT b_int FROM car_portal_app.b); 405 | 406 | ---------------------------------------------------------------------- 407 | 408 | DELETE FROM car_portal_app.a RETURNING *; 409 | 410 | ---------------------------------------------------------------------- 411 | 412 | TRUNCATE TABLE car_portal_app.a; 413 | 414 | ---------------------------------------------------------------------- 415 | 416 | TRUNCATE car_portal_app.a, car_portal_app.b; 417 | 418 | ---------------------------------------------------------------------- 419 | -------------------------------------------------------------------------------- /Chapter14/Testing/old_db.sql: -------------------------------------------------------------------------------- 1 | -- 2 | -- PostgreSQL database dump 3 | -- 4 | 5 | -- Dumped from database version 11.1 (Debian 11.1-1.pgdg90+1) 6 | -- Dumped by pg_dump version 11.1 (Debian 11.1-1.pgdg90+1) 7 | 8 | SET statement_timeout = 0; 9 | SET lock_timeout = 0; 10 | SET idle_in_transaction_session_timeout = 0; 11 | SET client_encoding = 'UTF8'; 12 | SET standard_conforming_strings = on; 13 | SELECT pg_catalog.set_config('search_path', '', false); 14 | SET check_function_bodies = false; 15 | SET client_min_messages = warning; 16 | SET row_security = off; 17 | 18 | -- 19 | -- Name: car_portal_app; Type: SCHEMA; Schema: -; Owner: car_portal_app 20 | -- 21 | 22 | CREATE SCHEMA car_portal_app; 23 | 24 | 25 | ALTER SCHEMA car_portal_app OWNER TO car_portal_app; 26 | 27 | -- 28 | -- Name: pgtap; Type: EXTENSION; Schema: -; Owner: 29 | -- 30 | 31 | CREATE EXTENSION IF NOT EXISTS pgtap WITH SCHEMA car_portal_app; 32 | 33 | 34 | -- 35 | -- Name: EXTENSION pgtap; Type: COMMENT; Schema: -; Owner: 36 | -- 37 | 38 | COMMENT ON EXTENSION pgtap IS 'Unit testing for PostgreSQL'; 39 | 40 | 41 | -- 42 | -- Name: increment_counter(); Type: FUNCTION; Schema: car_portal_app; Owner: car_portal_app 43 | -- 44 | 45 | CREATE FUNCTION car_portal_app.increment_counter() RETURNS void 46 | LANGUAGE plpgsql 47 | AS $$ 48 | BEGIN 49 | INSERT INTO counter_table SELECT count(*), now() FROM counter_table; 50 | END; 51 | $$; 52 | 53 | 54 | ALTER FUNCTION car_portal_app.increment_counter() OWNER TO car_portal_app; 55 | 56 | -- 57 | -- Name: test_increment(); Type: PROCEDURE; Schema: car_portal_app; Owner: car_portal_app 58 | -- 59 | 60 | CREATE PROCEDURE car_portal_app.test_increment() 61 | LANGUAGE plpgsql 62 | AS $$ 63 | DECLARE 64 | c int; m int; 65 | msg_text text; exception_detail text; exception_hint text; 66 | BEGIN 67 | RAISE NOTICE '1..3'; 68 | -- Test 1. Call increment function 69 | BEGIN 70 | PERFORM increment_counter(); 71 | RAISE NOTICE 'ok 1 - Call increment function'; 72 | EXCEPTION WHEN OTHERS THEN 73 | RAISE NOTICE 'not ok 1 - Call increment function'; 74 | GET STACKED DIAGNOSTICS 75 | msg_text = MESSAGE_TEXT, 76 | exception_detail = PG_EXCEPTION_DETAIL, 77 | exception_hint = PG_EXCEPTION_HINT; 78 | RAISE NOTICE 'Exception: % % %', msg_text, exception_detail, exception_hint; 79 | END; 80 | -- Test 2. The results are correct for the first record 81 | BEGIN 82 | SELECT COUNT(*), MAX(counter) INTO c, m FROM counter_table; 83 | IF NOT (c = 1 AND m = 0) THEN 84 | RAISE EXCEPTION 'Test 2: wrong values in output data for the first record'; 85 | END IF; 86 | RAISE NOTICE 'ok 2 - The results are correct for the first record'; 87 | EXCEPTION WHEN OTHERS THEN 88 | RAISE NOTICE 'not ok 2 - The results are correct for the first record'; 89 | GET STACKED DIAGNOSTICS 90 | msg_text = MESSAGE_TEXT, 91 | exception_detail = PG_EXCEPTION_DETAIL, 92 | exception_hint = PG_EXCEPTION_HINT; 93 | RAISE NOTICE 'Exception: % % %', msg_text, exception_detail, exception_hint; 94 | END; 95 | -- Test 3. The results are correct for the second record 96 | BEGIN 97 | PERFORM increment_counter(); 98 | SELECT COUNT(*), MAX(counter) INTO c, m FROM counter_table; 99 | IF NOT (c = 2 AND m = 1) THEN 100 | RAISE EXCEPTION 'Test 3: wrong values in output data for the second record'; 101 | END IF; 102 | RAISE NOTICE 'ok 3 - The results are correct for the second record'; 103 | EXCEPTION WHEN OTHERS THEN 104 | RAISE NOTICE 'not ok 3 - The results are correct for the second record'; 105 | GET STACKED DIAGNOSTICS 106 | msg_text = MESSAGE_TEXT, 107 | exception_detail = PG_EXCEPTION_DETAIL, 108 | exception_hint = PG_EXCEPTION_HINT; 109 | RAISE NOTICE 'Exception: % % %', msg_text, exception_detail, exception_hint; 110 | END; 111 | ROLLBACK; 112 | END; 113 | $$; 114 | 115 | 116 | ALTER PROCEDURE car_portal_app.test_increment() OWNER TO car_portal_app; 117 | 118 | SET default_tablespace = ''; 119 | 120 | SET default_with_oids = false; 121 | 122 | -- 123 | -- Name: account; Type: TABLE; Schema: car_portal_app; Owner: car_portal_app 124 | -- 125 | 126 | CREATE TABLE car_portal_app.account ( 127 | account_id integer NOT NULL, 128 | first_name text NOT NULL, 129 | last_name text NOT NULL, 130 | email text NOT NULL, 131 | password text NOT NULL, 132 | CONSTRAINT account_check CHECK (((first_name !~ '\s'::text) AND (last_name !~ '\s'::text))), 133 | CONSTRAINT account_email_check CHECK ((email ~* '^\w+@\w+[.]\w+$'::text)), 134 | CONSTRAINT account_password_check CHECK ((char_length(password) >= 8)) 135 | ); 136 | 137 | 138 | ALTER TABLE car_portal_app.account OWNER TO car_portal_app; 139 | 140 | -- 141 | -- Name: account_account_id_seq; Type: SEQUENCE; Schema: car_portal_app; Owner: car_portal_app 142 | -- 143 | 144 | ALTER TABLE car_portal_app.account ALTER COLUMN account_id ADD GENERATED BY DEFAULT AS IDENTITY ( 145 | SEQUENCE NAME car_portal_app.account_account_id_seq 146 | START WITH 1 147 | INCREMENT BY 1 148 | NO MINVALUE 149 | NO MAXVALUE 150 | CACHE 1 151 | ); 152 | 153 | 154 | -- 155 | -- Name: account_history; Type: TABLE; Schema: car_portal_app; Owner: car_portal_app 156 | -- 157 | 158 | CREATE TABLE car_portal_app.account_history ( 159 | account_history_id bigint NOT NULL, 160 | account_id integer NOT NULL, 161 | search_key text NOT NULL, 162 | search_date date NOT NULL 163 | ); 164 | 165 | 166 | ALTER TABLE car_portal_app.account_history OWNER TO car_portal_app; 167 | 168 | -- 169 | -- Name: account_history_account_history_id_seq; Type: SEQUENCE; Schema: car_portal_app; Owner: car_portal_app 170 | -- 171 | 172 | ALTER TABLE car_portal_app.account_history ALTER COLUMN account_history_id ADD GENERATED BY DEFAULT AS IDENTITY ( 173 | SEQUENCE NAME car_portal_app.account_history_account_history_id_seq 174 | START WITH 1 175 | INCREMENT BY 1 176 | NO MINVALUE 177 | NO MAXVALUE 178 | CACHE 1 179 | ); 180 | 181 | 182 | -- 183 | -- Name: advertisement; Type: TABLE; Schema: car_portal_app; Owner: car_portal_app 184 | -- 185 | 186 | CREATE TABLE car_portal_app.advertisement ( 187 | advertisement_id integer NOT NULL, 188 | advertisement_date timestamp with time zone NOT NULL, 189 | car_id integer NOT NULL, 190 | seller_account_id integer NOT NULL 191 | ); 192 | 193 | 194 | ALTER TABLE car_portal_app.advertisement OWNER TO car_portal_app; 195 | 196 | -- 197 | -- Name: advertisement_advertisement_id_seq; Type: SEQUENCE; Schema: car_portal_app; Owner: car_portal_app 198 | -- 199 | 200 | ALTER TABLE car_portal_app.advertisement ALTER COLUMN advertisement_id ADD GENERATED BY DEFAULT AS IDENTITY ( 201 | SEQUENCE NAME car_portal_app.advertisement_advertisement_id_seq 202 | START WITH 1 203 | INCREMENT BY 1 204 | NO MINVALUE 205 | NO MAXVALUE 206 | CACHE 1 207 | ); 208 | 209 | 210 | -- 211 | -- Name: advertisement_picture; Type: TABLE; Schema: car_portal_app; Owner: car_portal_app 212 | -- 213 | 214 | CREATE TABLE car_portal_app.advertisement_picture ( 215 | advertisement_picture_id integer NOT NULL, 216 | advertisement_id integer, 217 | picture_location text 218 | ); 219 | 220 | 221 | ALTER TABLE car_portal_app.advertisement_picture OWNER TO car_portal_app; 222 | 223 | -- 224 | -- Name: advertisement_picture_advertisement_picture_id_seq; Type: SEQUENCE; Schema: car_portal_app; Owner: car_portal_app 225 | -- 226 | 227 | ALTER TABLE car_portal_app.advertisement_picture ALTER COLUMN advertisement_picture_id ADD GENERATED BY DEFAULT AS IDENTITY ( 228 | SEQUENCE NAME car_portal_app.advertisement_picture_advertisement_picture_id_seq 229 | START WITH 1 230 | INCREMENT BY 1 231 | NO MINVALUE 232 | NO MAXVALUE 233 | CACHE 1 234 | ); 235 | 236 | 237 | -- 238 | -- Name: advertisement_rating; Type: TABLE; Schema: car_portal_app; Owner: car_portal_app 239 | -- 240 | 241 | CREATE TABLE car_portal_app.advertisement_rating ( 242 | advertisement_rating_id integer NOT NULL, 243 | advertisement_id integer NOT NULL, 244 | account_id integer NOT NULL, 245 | advertisement_rating_date date NOT NULL, 246 | rank integer NOT NULL, 247 | review text NOT NULL, 248 | CONSTRAINT advertisement_rating_rank_check CHECK ((rank = ANY (ARRAY[1, 2, 3, 4, 5]))), 249 | CONSTRAINT advertisement_rating_review_check CHECK ((char_length(review) <= 200)) 250 | ); 251 | 252 | 253 | ALTER TABLE car_portal_app.advertisement_rating OWNER TO car_portal_app; 254 | 255 | -- 256 | -- Name: advertisement_rating_advertisement_rating_id_seq; Type: SEQUENCE; Schema: car_portal_app; Owner: car_portal_app 257 | -- 258 | 259 | ALTER TABLE car_portal_app.advertisement_rating ALTER COLUMN advertisement_rating_id ADD GENERATED BY DEFAULT AS IDENTITY ( 260 | SEQUENCE NAME car_portal_app.advertisement_rating_advertisement_rating_id_seq 261 | START WITH 1 262 | INCREMENT BY 1 263 | NO MINVALUE 264 | NO MAXVALUE 265 | CACHE 1 266 | ); 267 | 268 | 269 | -- 270 | -- Name: car; Type: TABLE; Schema: car_portal_app; Owner: car_portal_app 271 | -- 272 | 273 | CREATE TABLE car_portal_app.car ( 274 | car_id integer NOT NULL, 275 | number_of_owners integer NOT NULL, 276 | registration_number text NOT NULL, 277 | manufacture_year integer NOT NULL, 278 | number_of_doors integer DEFAULT 5 NOT NULL, 279 | car_model_id integer NOT NULL, 280 | mileage integer 281 | ); 282 | 283 | 284 | ALTER TABLE car_portal_app.car OWNER TO car_portal_app; 285 | 286 | -- 287 | -- Name: car_car_id_seq; Type: SEQUENCE; Schema: car_portal_app; Owner: car_portal_app 288 | -- 289 | 290 | ALTER TABLE car_portal_app.car ALTER COLUMN car_id ADD GENERATED BY DEFAULT AS IDENTITY ( 291 | SEQUENCE NAME car_portal_app.car_car_id_seq 292 | START WITH 1 293 | INCREMENT BY 1 294 | NO MINVALUE 295 | NO MAXVALUE 296 | CACHE 1 297 | ); 298 | 299 | 300 | -- 301 | -- Name: car_model; Type: TABLE; Schema: car_portal_app; Owner: car_portal_app 302 | -- 303 | 304 | CREATE TABLE car_portal_app.car_model ( 305 | car_model_id integer NOT NULL, 306 | make text, 307 | model text 308 | ); 309 | 310 | 311 | ALTER TABLE car_portal_app.car_model OWNER TO car_portal_app; 312 | 313 | -- 314 | -- Name: car_model_car_model_id_seq; Type: SEQUENCE; Schema: car_portal_app; Owner: car_portal_app 315 | -- 316 | 317 | ALTER TABLE car_portal_app.car_model ALTER COLUMN car_model_id ADD GENERATED BY DEFAULT AS IDENTITY ( 318 | SEQUENCE NAME car_portal_app.car_model_car_model_id_seq 319 | START WITH 1 320 | INCREMENT BY 1 321 | NO MINVALUE 322 | NO MAXVALUE 323 | CACHE 1 324 | ); 325 | 326 | 327 | -- 328 | -- Name: counter_table; Type: TABLE; Schema: car_portal_app; Owner: car_portal_app 329 | -- 330 | 331 | CREATE TABLE car_portal_app.counter_table ( 332 | counter integer, 333 | insert_time timestamp with time zone NOT NULL 334 | ); 335 | 336 | 337 | ALTER TABLE car_portal_app.counter_table OWNER TO car_portal_app; 338 | 339 | -- 340 | -- Name: favorite_advertisement; Type: TABLE; Schema: car_portal_app; Owner: car_portal_app 341 | -- 342 | 343 | CREATE TABLE car_portal_app.favorite_advertisement ( 344 | account_id integer NOT NULL, 345 | advertisement_id integer NOT NULL 346 | ); 347 | 348 | 349 | ALTER TABLE car_portal_app.favorite_advertisement OWNER TO car_portal_app; 350 | 351 | -- 352 | -- Name: seller_account; Type: TABLE; Schema: car_portal_app; Owner: car_portal_app 353 | -- 354 | 355 | CREATE TABLE car_portal_app.seller_account ( 356 | seller_account_id integer NOT NULL, 357 | account_id integer NOT NULL, 358 | total_rank double precision, 359 | number_of_advertisement integer, 360 | street_name text NOT NULL, 361 | street_number text NOT NULL, 362 | zip_code text NOT NULL, 363 | city text NOT NULL 364 | ); 365 | 366 | 367 | ALTER TABLE car_portal_app.seller_account OWNER TO car_portal_app; 368 | 369 | -- 370 | -- Name: seller_account_seller_account_id_seq; Type: SEQUENCE; Schema: car_portal_app; Owner: car_portal_app 371 | -- 372 | 373 | ALTER TABLE car_portal_app.seller_account ALTER COLUMN seller_account_id ADD GENERATED BY DEFAULT AS IDENTITY ( 374 | SEQUENCE NAME car_portal_app.seller_account_seller_account_id_seq 375 | START WITH 1 376 | INCREMENT BY 1 377 | NO MINVALUE 378 | NO MAXVALUE 379 | CACHE 1 380 | ); 381 | 382 | 383 | -- 384 | -- Name: account account_email_key; Type: CONSTRAINT; Schema: car_portal_app; Owner: car_portal_app 385 | -- 386 | 387 | ALTER TABLE ONLY car_portal_app.account 388 | ADD CONSTRAINT account_email_key UNIQUE (email); 389 | 390 | 391 | -- 392 | -- Name: account_history account_history_account_id_search_key_search_date_key; Type: CONSTRAINT; Schema: car_portal_app; Owner: car_portal_app 393 | -- 394 | 395 | ALTER TABLE ONLY car_portal_app.account_history 396 | ADD CONSTRAINT account_history_account_id_search_key_search_date_key UNIQUE (account_id, search_key, search_date); 397 | 398 | 399 | -- 400 | -- Name: account_history account_history_pkey; Type: CONSTRAINT; Schema: car_portal_app; Owner: car_portal_app 401 | -- 402 | 403 | ALTER TABLE ONLY car_portal_app.account_history 404 | ADD CONSTRAINT account_history_pkey PRIMARY KEY (account_history_id); 405 | 406 | 407 | -- 408 | -- Name: account account_pkey; Type: CONSTRAINT; Schema: car_portal_app; Owner: car_portal_app 409 | -- 410 | 411 | ALTER TABLE ONLY car_portal_app.account 412 | ADD CONSTRAINT account_pkey PRIMARY KEY (account_id); 413 | 414 | 415 | -- 416 | -- Name: advertisement_picture advertisement_picture_picture_location_key; Type: CONSTRAINT; Schema: car_portal_app; Owner: car_portal_app 417 | -- 418 | 419 | ALTER TABLE ONLY car_portal_app.advertisement_picture 420 | ADD CONSTRAINT advertisement_picture_picture_location_key UNIQUE (picture_location); 421 | 422 | 423 | -- 424 | -- Name: advertisement_picture advertisement_picture_pkey; Type: CONSTRAINT; Schema: car_portal_app; Owner: car_portal_app 425 | -- 426 | 427 | ALTER TABLE ONLY car_portal_app.advertisement_picture 428 | ADD CONSTRAINT advertisement_picture_pkey PRIMARY KEY (advertisement_picture_id); 429 | 430 | 431 | -- 432 | -- Name: advertisement advertisement_pkey; Type: CONSTRAINT; Schema: car_portal_app; Owner: car_portal_app 433 | -- 434 | 435 | ALTER TABLE ONLY car_portal_app.advertisement 436 | ADD CONSTRAINT advertisement_pkey PRIMARY KEY (advertisement_id); 437 | 438 | 439 | -- 440 | -- Name: advertisement_rating advertisement_rating_pkey; Type: CONSTRAINT; Schema: car_portal_app; Owner: car_portal_app 441 | -- 442 | 443 | ALTER TABLE ONLY car_portal_app.advertisement_rating 444 | ADD CONSTRAINT advertisement_rating_pkey PRIMARY KEY (advertisement_rating_id); 445 | 446 | 447 | -- 448 | -- Name: car_model car_model_make_model_key; Type: CONSTRAINT; Schema: car_portal_app; Owner: car_portal_app 449 | -- 450 | 451 | ALTER TABLE ONLY car_portal_app.car_model 452 | ADD CONSTRAINT car_model_make_model_key UNIQUE (make, model); 453 | 454 | 455 | -- 456 | -- Name: car_model car_model_pkey; Type: CONSTRAINT; Schema: car_portal_app; Owner: car_portal_app 457 | -- 458 | 459 | ALTER TABLE ONLY car_portal_app.car_model 460 | ADD CONSTRAINT car_model_pkey PRIMARY KEY (car_model_id); 461 | 462 | 463 | -- 464 | -- Name: car car_pkey; Type: CONSTRAINT; Schema: car_portal_app; Owner: car_portal_app 465 | -- 466 | 467 | ALTER TABLE ONLY car_portal_app.car 468 | ADD CONSTRAINT car_pkey PRIMARY KEY (car_id); 469 | 470 | 471 | -- 472 | -- Name: car car_registration_number_key; Type: CONSTRAINT; Schema: car_portal_app; Owner: car_portal_app 473 | -- 474 | 475 | ALTER TABLE ONLY car_portal_app.car 476 | ADD CONSTRAINT car_registration_number_key UNIQUE (registration_number); 477 | 478 | 479 | -- 480 | -- Name: favorite_advertisement favorite_advertisement_pkey; Type: CONSTRAINT; Schema: car_portal_app; Owner: car_portal_app 481 | -- 482 | 483 | ALTER TABLE ONLY car_portal_app.favorite_advertisement 484 | ADD CONSTRAINT favorite_advertisement_pkey PRIMARY KEY (account_id, advertisement_id); 485 | 486 | 487 | -- 488 | -- Name: seller_account seller_account_pkey; Type: CONSTRAINT; Schema: car_portal_app; Owner: car_portal_app 489 | -- 490 | 491 | ALTER TABLE ONLY car_portal_app.seller_account 492 | ADD CONSTRAINT seller_account_pkey PRIMARY KEY (seller_account_id); 493 | 494 | 495 | -- 496 | -- Name: account_history account_history_account_id_fkey; Type: FK CONSTRAINT; Schema: car_portal_app; Owner: car_portal_app 497 | -- 498 | 499 | ALTER TABLE ONLY car_portal_app.account_history 500 | ADD CONSTRAINT account_history_account_id_fkey FOREIGN KEY (account_id) REFERENCES car_portal_app.account(account_id); 501 | 502 | 503 | -- 504 | -- Name: advertisement advertisement_car_id_fkey; Type: FK CONSTRAINT; Schema: car_portal_app; Owner: car_portal_app 505 | -- 506 | 507 | ALTER TABLE ONLY car_portal_app.advertisement 508 | ADD CONSTRAINT advertisement_car_id_fkey FOREIGN KEY (car_id) REFERENCES car_portal_app.car(car_id); 509 | 510 | 511 | -- 512 | -- Name: advertisement_picture advertisement_picture_advertisement_id_fkey; Type: FK CONSTRAINT; Schema: car_portal_app; Owner: car_portal_app 513 | -- 514 | 515 | ALTER TABLE ONLY car_portal_app.advertisement_picture 516 | ADD CONSTRAINT advertisement_picture_advertisement_id_fkey FOREIGN KEY (advertisement_id) REFERENCES car_portal_app.advertisement(advertisement_id); 517 | 518 | 519 | -- 520 | -- Name: advertisement_rating advertisement_rating_account_id_fkey; Type: FK CONSTRAINT; Schema: car_portal_app; Owner: car_portal_app 521 | -- 522 | 523 | ALTER TABLE ONLY car_portal_app.advertisement_rating 524 | ADD CONSTRAINT advertisement_rating_account_id_fkey FOREIGN KEY (account_id) REFERENCES car_portal_app.account(account_id); 525 | 526 | 527 | -- 528 | -- Name: advertisement_rating advertisement_rating_advertisement_id_fkey; Type: FK CONSTRAINT; Schema: car_portal_app; Owner: car_portal_app 529 | -- 530 | 531 | ALTER TABLE ONLY car_portal_app.advertisement_rating 532 | ADD CONSTRAINT advertisement_rating_advertisement_id_fkey FOREIGN KEY (advertisement_id) REFERENCES car_portal_app.advertisement(advertisement_id); 533 | 534 | 535 | -- 536 | -- Name: advertisement advertisement_seller_account_id_fkey; Type: FK CONSTRAINT; Schema: car_portal_app; Owner: car_portal_app 537 | -- 538 | 539 | ALTER TABLE ONLY car_portal_app.advertisement 540 | ADD CONSTRAINT advertisement_seller_account_id_fkey FOREIGN KEY (seller_account_id) REFERENCES car_portal_app.seller_account(seller_account_id); 541 | 542 | 543 | -- 544 | -- Name: car car_car_model_id_fkey; Type: FK CONSTRAINT; Schema: car_portal_app; Owner: car_portal_app 545 | -- 546 | 547 | ALTER TABLE ONLY car_portal_app.car 548 | ADD CONSTRAINT car_car_model_id_fkey FOREIGN KEY (car_model_id) REFERENCES car_portal_app.car_model(car_model_id); 549 | 550 | 551 | -- 552 | -- Name: favorite_advertisement favorite_advertisement_account_id_fkey; Type: FK CONSTRAINT; Schema: car_portal_app; Owner: car_portal_app 553 | -- 554 | 555 | ALTER TABLE ONLY car_portal_app.favorite_advertisement 556 | ADD CONSTRAINT favorite_advertisement_account_id_fkey FOREIGN KEY (account_id) REFERENCES car_portal_app.account(account_id); 557 | 558 | 559 | -- 560 | -- Name: favorite_advertisement favorite_advertisement_advertisement_id_fkey; Type: FK CONSTRAINT; Schema: car_portal_app; Owner: car_portal_app 561 | -- 562 | 563 | ALTER TABLE ONLY car_portal_app.favorite_advertisement 564 | ADD CONSTRAINT favorite_advertisement_advertisement_id_fkey FOREIGN KEY (advertisement_id) REFERENCES car_portal_app.advertisement(advertisement_id); 565 | 566 | 567 | -- 568 | -- Name: seller_account seller_account_account_id_fkey; Type: FK CONSTRAINT; Schema: car_portal_app; Owner: car_portal_app 569 | -- 570 | 571 | ALTER TABLE ONLY car_portal_app.seller_account 572 | ADD CONSTRAINT seller_account_account_id_fkey FOREIGN KEY (account_id) REFERENCES car_portal_app.account(account_id); 573 | 574 | 575 | -- 576 | -- PostgreSQL database dump complete 577 | -- 578 | 579 | -------------------------------------------------------------------------------- /Chapter14/Testing/new_db.sql: -------------------------------------------------------------------------------- 1 | -- 2 | -- PostgreSQL database dump 3 | -- 4 | 5 | -- Dumped from database version 11.1 (Debian 11.1-1.pgdg90+1) 6 | -- Dumped by pg_dump version 11.1 (Debian 11.1-1.pgdg90+1) 7 | 8 | SET statement_timeout = 0; 9 | SET lock_timeout = 0; 10 | SET idle_in_transaction_session_timeout = 0; 11 | SET client_encoding = 'UTF8'; 12 | SET standard_conforming_strings = on; 13 | SELECT pg_catalog.set_config('search_path', '', false); 14 | SET check_function_bodies = false; 15 | SET client_min_messages = warning; 16 | SET row_security = off; 17 | 18 | -- 19 | -- Name: car_portal_app; Type: SCHEMA; Schema: -; Owner: car_portal_app 20 | -- 21 | 22 | CREATE SCHEMA car_portal_app; 23 | 24 | 25 | ALTER SCHEMA car_portal_app OWNER TO car_portal_app; 26 | 27 | -- 28 | -- Name: pgtap; Type: EXTENSION; Schema: -; Owner: 29 | -- 30 | 31 | CREATE EXTENSION IF NOT EXISTS pgtap WITH SCHEMA car_portal_app; 32 | 33 | 34 | -- 35 | -- Name: EXTENSION pgtap; Type: COMMENT; Schema: -; Owner: 36 | -- 37 | 38 | COMMENT ON EXTENSION pgtap IS 'Unit testing for PostgreSQL'; 39 | 40 | 41 | -- 42 | -- Name: increment_counter(); Type: FUNCTION; Schema: car_portal_app; Owner: car_portal_app 43 | -- 44 | 45 | CREATE FUNCTION car_portal_app.increment_counter() RETURNS void 46 | LANGUAGE plpgsql 47 | AS $$ 48 | BEGIN 49 | INSERT INTO counter_table SELECT count(*), now() FROM counter_table; 50 | END; 51 | $$; 52 | 53 | 54 | ALTER FUNCTION car_portal_app.increment_counter() OWNER TO car_portal_app; 55 | 56 | -- 57 | -- Name: test_increment(); Type: PROCEDURE; Schema: car_portal_app; Owner: car_portal_app 58 | -- 59 | 60 | CREATE PROCEDURE car_portal_app.test_increment() 61 | LANGUAGE plpgsql 62 | AS $$ 63 | DECLARE 64 | c int; m int; 65 | msg_text text; exception_detail text; exception_hint text; 66 | BEGIN 67 | RAISE NOTICE '1..3'; 68 | -- Test 1. Call increment function 69 | BEGIN 70 | PERFORM increment_counter(); 71 | RAISE NOTICE 'ok 1 - Call increment function'; 72 | EXCEPTION WHEN OTHERS THEN 73 | RAISE NOTICE 'not ok 1 - Call increment function'; 74 | GET STACKED DIAGNOSTICS 75 | msg_text = MESSAGE_TEXT, 76 | exception_detail = PG_EXCEPTION_DETAIL, 77 | exception_hint = PG_EXCEPTION_HINT; 78 | RAISE NOTICE 'Exception: % % %', msg_text, exception_detail, exception_hint; 79 | END; 80 | -- Test 2. The results are correct for the first record 81 | BEGIN 82 | SELECT COUNT(*), MAX(counter) INTO c, m FROM counter_table; 83 | IF NOT (c = 1 AND m = 0) THEN 84 | RAISE EXCEPTION 'Test 2: wrong values in output data for the first record'; 85 | END IF; 86 | RAISE NOTICE 'ok 2 - The results are correct for the first record'; 87 | EXCEPTION WHEN OTHERS THEN 88 | RAISE NOTICE 'not ok 2 - The results are correct for the first record'; 89 | GET STACKED DIAGNOSTICS 90 | msg_text = MESSAGE_TEXT, 91 | exception_detail = PG_EXCEPTION_DETAIL, 92 | exception_hint = PG_EXCEPTION_HINT; 93 | RAISE NOTICE 'Exception: % % %', msg_text, exception_detail, exception_hint; 94 | END; 95 | -- Test 3. The results are correct for the second record 96 | BEGIN 97 | PERFORM increment_counter(); 98 | SELECT COUNT(*), MAX(counter) INTO c, m FROM counter_table; 99 | IF NOT (c = 2 AND m = 1) THEN 100 | RAISE EXCEPTION 'Test 3: wrong values in output data for the second record'; 101 | END IF; 102 | RAISE NOTICE 'ok 3 - The results are correct for the second record'; 103 | EXCEPTION WHEN OTHERS THEN 104 | RAISE NOTICE 'not ok 3 - The results are correct for the second record'; 105 | GET STACKED DIAGNOSTICS 106 | msg_text = MESSAGE_TEXT, 107 | exception_detail = PG_EXCEPTION_DETAIL, 108 | exception_hint = PG_EXCEPTION_HINT; 109 | RAISE NOTICE 'Exception: % % %', msg_text, exception_detail, exception_hint; 110 | END; 111 | ROLLBACK; 112 | END; 113 | $$; 114 | 115 | 116 | ALTER PROCEDURE car_portal_app.test_increment() OWNER TO car_portal_app; 117 | 118 | SET default_tablespace = ''; 119 | 120 | SET default_with_oids = false; 121 | 122 | -- 123 | -- Name: account; Type: TABLE; Schema: car_portal_app; Owner: car_portal_app 124 | -- 125 | 126 | CREATE TABLE car_portal_app.account ( 127 | account_id integer NOT NULL, 128 | first_name text NOT NULL, 129 | last_name text NOT NULL, 130 | email text NOT NULL, 131 | password text NOT NULL, 132 | CONSTRAINT account_check CHECK (((first_name !~ '\s'::text) AND (last_name !~ '\s'::text))), 133 | CONSTRAINT account_email_check CHECK ((email ~* '^\w+@\w+[.]\w+$'::text)), 134 | CONSTRAINT account_password_check CHECK ((char_length(password) >= 8)) 135 | ); 136 | 137 | 138 | ALTER TABLE car_portal_app.account OWNER TO car_portal_app; 139 | 140 | -- 141 | -- Name: account_account_id_seq; Type: SEQUENCE; Schema: car_portal_app; Owner: car_portal_app 142 | -- 143 | 144 | ALTER TABLE car_portal_app.account ALTER COLUMN account_id ADD GENERATED BY DEFAULT AS IDENTITY ( 145 | SEQUENCE NAME car_portal_app.account_account_id_seq 146 | START WITH 1 147 | INCREMENT BY 1 148 | NO MINVALUE 149 | NO MAXVALUE 150 | CACHE 1 151 | ); 152 | 153 | 154 | -- 155 | -- Name: account_history; Type: TABLE; Schema: car_portal_app; Owner: car_portal_app 156 | -- 157 | 158 | CREATE TABLE car_portal_app.account_history ( 159 | account_history_id bigint NOT NULL, 160 | account_id integer NOT NULL, 161 | search_key text NOT NULL, 162 | search_date date NOT NULL 163 | ); 164 | 165 | 166 | ALTER TABLE car_portal_app.account_history OWNER TO car_portal_app; 167 | 168 | -- 169 | -- Name: account_history_account_history_id_seq; Type: SEQUENCE; Schema: car_portal_app; Owner: car_portal_app 170 | -- 171 | 172 | ALTER TABLE car_portal_app.account_history ALTER COLUMN account_history_id ADD GENERATED BY DEFAULT AS IDENTITY ( 173 | SEQUENCE NAME car_portal_app.account_history_account_history_id_seq 174 | START WITH 1 175 | INCREMENT BY 1 176 | NO MINVALUE 177 | NO MAXVALUE 178 | CACHE 1 179 | ); 180 | 181 | 182 | -- 183 | -- Name: advertisement; Type: TABLE; Schema: car_portal_app; Owner: car_portal_app 184 | -- 185 | 186 | CREATE TABLE car_portal_app.advertisement ( 187 | advertisement_id integer NOT NULL, 188 | advertisement_date timestamp with time zone NOT NULL, 189 | car_id integer NOT NULL, 190 | seller_account_id integer NOT NULL 191 | ); 192 | 193 | 194 | ALTER TABLE car_portal_app.advertisement OWNER TO car_portal_app; 195 | 196 | -- 197 | -- Name: advertisement_advertisement_id_seq; Type: SEQUENCE; Schema: car_portal_app; Owner: car_portal_app 198 | -- 199 | 200 | ALTER TABLE car_portal_app.advertisement ALTER COLUMN advertisement_id ADD GENERATED BY DEFAULT AS IDENTITY ( 201 | SEQUENCE NAME car_portal_app.advertisement_advertisement_id_seq 202 | START WITH 1 203 | INCREMENT BY 1 204 | NO MINVALUE 205 | NO MAXVALUE 206 | CACHE 1 207 | ); 208 | 209 | 210 | -- 211 | -- Name: advertisement_picture; Type: TABLE; Schema: car_portal_app; Owner: car_portal_app 212 | -- 213 | 214 | CREATE TABLE car_portal_app.advertisement_picture ( 215 | advertisement_picture_id integer NOT NULL, 216 | advertisement_id integer, 217 | picture_location text 218 | ); 219 | 220 | 221 | ALTER TABLE car_portal_app.advertisement_picture OWNER TO car_portal_app; 222 | 223 | -- 224 | -- Name: advertisement_picture_advertisement_picture_id_seq; Type: SEQUENCE; Schema: car_portal_app; Owner: car_portal_app 225 | -- 226 | 227 | ALTER TABLE car_portal_app.advertisement_picture ALTER COLUMN advertisement_picture_id ADD GENERATED BY DEFAULT AS IDENTITY ( 228 | SEQUENCE NAME car_portal_app.advertisement_picture_advertisement_picture_id_seq 229 | START WITH 1 230 | INCREMENT BY 1 231 | NO MINVALUE 232 | NO MAXVALUE 233 | CACHE 1 234 | ); 235 | 236 | 237 | -- 238 | -- Name: advertisement_rating; Type: TABLE; Schema: car_portal_app; Owner: car_portal_app 239 | -- 240 | 241 | CREATE TABLE car_portal_app.advertisement_rating ( 242 | advertisement_rating_id integer NOT NULL, 243 | advertisement_id integer NOT NULL, 244 | account_id integer NOT NULL, 245 | advertisement_rating_date date NOT NULL, 246 | rank integer NOT NULL, 247 | review text NOT NULL, 248 | CONSTRAINT advertisement_rating_rank_check CHECK ((rank = ANY (ARRAY[1, 2, 3, 4, 5]))), 249 | CONSTRAINT advertisement_rating_review_check CHECK ((char_length(review) <= 200)) 250 | ); 251 | 252 | 253 | ALTER TABLE car_portal_app.advertisement_rating OWNER TO car_portal_app; 254 | 255 | -- 256 | -- Name: advertisement_rating_advertisement_rating_id_seq; Type: SEQUENCE; Schema: car_portal_app; Owner: car_portal_app 257 | -- 258 | 259 | ALTER TABLE car_portal_app.advertisement_rating ALTER COLUMN advertisement_rating_id ADD GENERATED BY DEFAULT AS IDENTITY ( 260 | SEQUENCE NAME car_portal_app.advertisement_rating_advertisement_rating_id_seq 261 | START WITH 1 262 | INCREMENT BY 1 263 | NO MINVALUE 264 | NO MAXVALUE 265 | CACHE 1 266 | ); 267 | 268 | 269 | -- 270 | -- Name: car; Type: TABLE; Schema: car_portal_app; Owner: car_portal_app 271 | -- 272 | 273 | CREATE TABLE car_portal_app.car ( 274 | car_id integer NOT NULL, 275 | number_of_owners integer NOT NULL, 276 | registration_number text NOT NULL, 277 | manufacture_year integer NOT NULL, 278 | number_of_doors integer DEFAULT 5 NOT NULL, 279 | car_model_id integer NOT NULL, 280 | mileage integer, 281 | insert_date timestamp with time zone DEFAULT now() 282 | ); 283 | 284 | 285 | ALTER TABLE car_portal_app.car OWNER TO car_portal_app; 286 | 287 | -- 288 | -- Name: car_car_id_seq; Type: SEQUENCE; Schema: car_portal_app; Owner: car_portal_app 289 | -- 290 | 291 | ALTER TABLE car_portal_app.car ALTER COLUMN car_id ADD GENERATED BY DEFAULT AS IDENTITY ( 292 | SEQUENCE NAME car_portal_app.car_car_id_seq 293 | START WITH 1 294 | INCREMENT BY 1 295 | NO MINVALUE 296 | NO MAXVALUE 297 | CACHE 1 298 | ); 299 | 300 | 301 | -- 302 | -- Name: car_model; Type: TABLE; Schema: car_portal_app; Owner: car_portal_app 303 | -- 304 | 305 | CREATE TABLE car_portal_app.car_model ( 306 | car_model_id integer NOT NULL, 307 | make text, 308 | model text 309 | ); 310 | 311 | 312 | ALTER TABLE car_portal_app.car_model OWNER TO car_portal_app; 313 | 314 | -- 315 | -- Name: car_model_car_model_id_seq; Type: SEQUENCE; Schema: car_portal_app; Owner: car_portal_app 316 | -- 317 | 318 | ALTER TABLE car_portal_app.car_model ALTER COLUMN car_model_id ADD GENERATED BY DEFAULT AS IDENTITY ( 319 | SEQUENCE NAME car_portal_app.car_model_car_model_id_seq 320 | START WITH 1 321 | INCREMENT BY 1 322 | NO MINVALUE 323 | NO MAXVALUE 324 | CACHE 1 325 | ); 326 | 327 | 328 | -- 329 | -- Name: counter_table; Type: TABLE; Schema: car_portal_app; Owner: car_portal_app 330 | -- 331 | 332 | CREATE TABLE car_portal_app.counter_table ( 333 | counter integer, 334 | insert_time timestamp with time zone NOT NULL 335 | ); 336 | 337 | 338 | ALTER TABLE car_portal_app.counter_table OWNER TO car_portal_app; 339 | 340 | -- 341 | -- Name: favorite_advertisement; Type: TABLE; Schema: car_portal_app; Owner: car_portal_app 342 | -- 343 | 344 | CREATE TABLE car_portal_app.favorite_advertisement ( 345 | account_id integer NOT NULL, 346 | advertisement_id integer NOT NULL 347 | ); 348 | 349 | 350 | ALTER TABLE car_portal_app.favorite_advertisement OWNER TO car_portal_app; 351 | 352 | -- 353 | -- Name: seller_account; Type: TABLE; Schema: car_portal_app; Owner: car_portal_app 354 | -- 355 | 356 | CREATE TABLE car_portal_app.seller_account ( 357 | seller_account_id integer NOT NULL, 358 | account_id integer NOT NULL, 359 | total_rank double precision, 360 | number_of_advertisement integer, 361 | street_name text NOT NULL, 362 | street_number text NOT NULL, 363 | zip_code text NOT NULL, 364 | city text NOT NULL 365 | ); 366 | 367 | 368 | ALTER TABLE car_portal_app.seller_account OWNER TO car_portal_app; 369 | 370 | -- 371 | -- Name: seller_account_seller_account_id_seq; Type: SEQUENCE; Schema: car_portal_app; Owner: car_portal_app 372 | -- 373 | 374 | ALTER TABLE car_portal_app.seller_account ALTER COLUMN seller_account_id ADD GENERATED BY DEFAULT AS IDENTITY ( 375 | SEQUENCE NAME car_portal_app.seller_account_seller_account_id_seq 376 | START WITH 1 377 | INCREMENT BY 1 378 | NO MINVALUE 379 | NO MAXVALUE 380 | CACHE 1 381 | ); 382 | 383 | 384 | -- 385 | -- Name: account account_email_key; Type: CONSTRAINT; Schema: car_portal_app; Owner: car_portal_app 386 | -- 387 | 388 | ALTER TABLE ONLY car_portal_app.account 389 | ADD CONSTRAINT account_email_key UNIQUE (email); 390 | 391 | 392 | -- 393 | -- Name: account_history account_history_account_id_search_key_search_date_key; Type: CONSTRAINT; Schema: car_portal_app; Owner: car_portal_app 394 | -- 395 | 396 | ALTER TABLE ONLY car_portal_app.account_history 397 | ADD CONSTRAINT account_history_account_id_search_key_search_date_key UNIQUE (account_id, search_key, search_date); 398 | 399 | 400 | -- 401 | -- Name: account_history account_history_pkey; Type: CONSTRAINT; Schema: car_portal_app; Owner: car_portal_app 402 | -- 403 | 404 | ALTER TABLE ONLY car_portal_app.account_history 405 | ADD CONSTRAINT account_history_pkey PRIMARY KEY (account_history_id); 406 | 407 | 408 | -- 409 | -- Name: account account_pkey; Type: CONSTRAINT; Schema: car_portal_app; Owner: car_portal_app 410 | -- 411 | 412 | ALTER TABLE ONLY car_portal_app.account 413 | ADD CONSTRAINT account_pkey PRIMARY KEY (account_id); 414 | 415 | 416 | -- 417 | -- Name: advertisement_picture advertisement_picture_picture_location_key; Type: CONSTRAINT; Schema: car_portal_app; Owner: car_portal_app 418 | -- 419 | 420 | ALTER TABLE ONLY car_portal_app.advertisement_picture 421 | ADD CONSTRAINT advertisement_picture_picture_location_key UNIQUE (picture_location); 422 | 423 | 424 | -- 425 | -- Name: advertisement_picture advertisement_picture_pkey; Type: CONSTRAINT; Schema: car_portal_app; Owner: car_portal_app 426 | -- 427 | 428 | ALTER TABLE ONLY car_portal_app.advertisement_picture 429 | ADD CONSTRAINT advertisement_picture_pkey PRIMARY KEY (advertisement_picture_id); 430 | 431 | 432 | -- 433 | -- Name: advertisement advertisement_pkey; Type: CONSTRAINT; Schema: car_portal_app; Owner: car_portal_app 434 | -- 435 | 436 | ALTER TABLE ONLY car_portal_app.advertisement 437 | ADD CONSTRAINT advertisement_pkey PRIMARY KEY (advertisement_id); 438 | 439 | 440 | -- 441 | -- Name: advertisement_rating advertisement_rating_pkey; Type: CONSTRAINT; Schema: car_portal_app; Owner: car_portal_app 442 | -- 443 | 444 | ALTER TABLE ONLY car_portal_app.advertisement_rating 445 | ADD CONSTRAINT advertisement_rating_pkey PRIMARY KEY (advertisement_rating_id); 446 | 447 | 448 | -- 449 | -- Name: car_model car_model_make_model_key; Type: CONSTRAINT; Schema: car_portal_app; Owner: car_portal_app 450 | -- 451 | 452 | ALTER TABLE ONLY car_portal_app.car_model 453 | ADD CONSTRAINT car_model_make_model_key UNIQUE (make, model); 454 | 455 | 456 | -- 457 | -- Name: car_model car_model_pkey; Type: CONSTRAINT; Schema: car_portal_app; Owner: car_portal_app 458 | -- 459 | 460 | ALTER TABLE ONLY car_portal_app.car_model 461 | ADD CONSTRAINT car_model_pkey PRIMARY KEY (car_model_id); 462 | 463 | 464 | -- 465 | -- Name: car car_pkey; Type: CONSTRAINT; Schema: car_portal_app; Owner: car_portal_app 466 | -- 467 | 468 | ALTER TABLE ONLY car_portal_app.car 469 | ADD CONSTRAINT car_pkey PRIMARY KEY (car_id); 470 | 471 | 472 | -- 473 | -- Name: car car_registration_number_key; Type: CONSTRAINT; Schema: car_portal_app; Owner: car_portal_app 474 | -- 475 | 476 | ALTER TABLE ONLY car_portal_app.car 477 | ADD CONSTRAINT car_registration_number_key UNIQUE (registration_number); 478 | 479 | 480 | -- 481 | -- Name: favorite_advertisement favorite_advertisement_pkey; Type: CONSTRAINT; Schema: car_portal_app; Owner: car_portal_app 482 | -- 483 | 484 | ALTER TABLE ONLY car_portal_app.favorite_advertisement 485 | ADD CONSTRAINT favorite_advertisement_pkey PRIMARY KEY (account_id, advertisement_id); 486 | 487 | 488 | -- 489 | -- Name: seller_account seller_account_pkey; Type: CONSTRAINT; Schema: car_portal_app; Owner: car_portal_app 490 | -- 491 | 492 | ALTER TABLE ONLY car_portal_app.seller_account 493 | ADD CONSTRAINT seller_account_pkey PRIMARY KEY (seller_account_id); 494 | 495 | 496 | -- 497 | -- Name: account_history account_history_account_id_fkey; Type: FK CONSTRAINT; Schema: car_portal_app; Owner: car_portal_app 498 | -- 499 | 500 | ALTER TABLE ONLY car_portal_app.account_history 501 | ADD CONSTRAINT account_history_account_id_fkey FOREIGN KEY (account_id) REFERENCES car_portal_app.account(account_id); 502 | 503 | 504 | -- 505 | -- Name: advertisement advertisement_car_id_fkey; Type: FK CONSTRAINT; Schema: car_portal_app; Owner: car_portal_app 506 | -- 507 | 508 | ALTER TABLE ONLY car_portal_app.advertisement 509 | ADD CONSTRAINT advertisement_car_id_fkey FOREIGN KEY (car_id) REFERENCES car_portal_app.car(car_id); 510 | 511 | 512 | -- 513 | -- Name: advertisement_picture advertisement_picture_advertisement_id_fkey; Type: FK CONSTRAINT; Schema: car_portal_app; Owner: car_portal_app 514 | -- 515 | 516 | ALTER TABLE ONLY car_portal_app.advertisement_picture 517 | ADD CONSTRAINT advertisement_picture_advertisement_id_fkey FOREIGN KEY (advertisement_id) REFERENCES car_portal_app.advertisement(advertisement_id); 518 | 519 | 520 | -- 521 | -- Name: advertisement_rating advertisement_rating_account_id_fkey; Type: FK CONSTRAINT; Schema: car_portal_app; Owner: car_portal_app 522 | -- 523 | 524 | ALTER TABLE ONLY car_portal_app.advertisement_rating 525 | ADD CONSTRAINT advertisement_rating_account_id_fkey FOREIGN KEY (account_id) REFERENCES car_portal_app.account(account_id); 526 | 527 | 528 | -- 529 | -- Name: advertisement_rating advertisement_rating_advertisement_id_fkey; Type: FK CONSTRAINT; Schema: car_portal_app; Owner: car_portal_app 530 | -- 531 | 532 | ALTER TABLE ONLY car_portal_app.advertisement_rating 533 | ADD CONSTRAINT advertisement_rating_advertisement_id_fkey FOREIGN KEY (advertisement_id) REFERENCES car_portal_app.advertisement(advertisement_id); 534 | 535 | 536 | -- 537 | -- Name: advertisement advertisement_seller_account_id_fkey; Type: FK CONSTRAINT; Schema: car_portal_app; Owner: car_portal_app 538 | -- 539 | 540 | ALTER TABLE ONLY car_portal_app.advertisement 541 | ADD CONSTRAINT advertisement_seller_account_id_fkey FOREIGN KEY (seller_account_id) REFERENCES car_portal_app.seller_account(seller_account_id); 542 | 543 | 544 | -- 545 | -- Name: car car_car_model_id_fkey; Type: FK CONSTRAINT; Schema: car_portal_app; Owner: car_portal_app 546 | -- 547 | 548 | ALTER TABLE ONLY car_portal_app.car 549 | ADD CONSTRAINT car_car_model_id_fkey FOREIGN KEY (car_model_id) REFERENCES car_portal_app.car_model(car_model_id); 550 | 551 | 552 | -- 553 | -- Name: favorite_advertisement favorite_advertisement_account_id_fkey; Type: FK CONSTRAINT; Schema: car_portal_app; Owner: car_portal_app 554 | -- 555 | 556 | ALTER TABLE ONLY car_portal_app.favorite_advertisement 557 | ADD CONSTRAINT favorite_advertisement_account_id_fkey FOREIGN KEY (account_id) REFERENCES car_portal_app.account(account_id); 558 | 559 | 560 | -- 561 | -- Name: favorite_advertisement favorite_advertisement_advertisement_id_fkey; Type: FK CONSTRAINT; Schema: car_portal_app; Owner: car_portal_app 562 | -- 563 | 564 | ALTER TABLE ONLY car_portal_app.favorite_advertisement 565 | ADD CONSTRAINT favorite_advertisement_advertisement_id_fkey FOREIGN KEY (advertisement_id) REFERENCES car_portal_app.advertisement(advertisement_id); 566 | 567 | 568 | -- 569 | -- Name: seller_account seller_account_account_id_fkey; Type: FK CONSTRAINT; Schema: car_portal_app; Owner: car_portal_app 570 | -- 571 | 572 | ALTER TABLE ONLY car_portal_app.seller_account 573 | ADD CONSTRAINT seller_account_account_id_fkey FOREIGN KEY (account_id) REFERENCES car_portal_app.account(account_id); 574 | 575 | 576 | -- 577 | -- PostgreSQL database dump complete 578 | -- 579 | 580 | --------------------------------------------------------------------------------