├── Expected results.pdf ├── Handling NULL.md ├── Links of interest.md ├── Normalization and design ├── Anomalies in DBMS.pdf ├── Oracle DMRDD.pdf ├── Oracle Normalization.pdf └── README.md ├── Old-school SQL syntax.md ├── On-the-board ├── 2024-09-26.sql ├── 2024-10-01.sql ├── 2024-10-10.sql ├── 2024-11-07.sql ├── 2024-11-14.sql ├── 2024-12-05.sql ├── 2024-12-17.sql ├── 2024-12-19.sql ├── 2025-01-07.sql ├── 2025-01-09.sql ├── 2025-01-14.sql ├── 2025-01-21.md ├── 2025-01-30.sql ├── 2025-02-24.sql ├── 2025-02-26.sql ├── 2025-03-10.sql └── state-machine │ ├── State machine II-2.sql │ └── State machine II.sql ├── PostgreSQL Python.md ├── README.md ├── Regular expressions ├── RegExp Cheat Sheet.pdf └── regex.sql ├── Resources.pdf ├── W3Schools demo DB DDL ├── Northwind.png ├── Northwind.postgres.sql ├── README.md └── W3S-Postgres-dd.sql ├── Window functions TODO.md ├── You may also like └── readme.md ├── join ├── Cooking ERD.png ├── Cooking data model DDL.sql ├── Joins.png └── README.md ├── miscellaneous ├── About ETL │ ├── about-ETL.sql │ ├── fl_data.txt │ └── mixed cultures.csv ├── Converting JSON documents to relational tables │ ├── Formatted JSONtest.zip │ └── Readme.md ├── Custom aggregate.md ├── Custom operators.md ├── Discrepancies │ ├── Martin.Grigorov │ │ ├── HW-Script-1.sql │ │ └── HW-Script-2.sql │ ├── S. Stefanov │ │ └── discrepancies.sql │ └── Svetoslav.XI-V │ │ └── Discrepancies.sql ├── JSONB misc.sql ├── Refresh ECB forex.php ├── Table for recursive CTE.sql ├── cooking │ └── Касърова 1933.pdf ├── food deliveries │ ├── Lunch A.sql │ ├── Lunch B.sql │ └── Lunch-V.sql ├── foreign data.sql ├── notifications │ ├── listener.php │ ├── listeners.md │ ├── publisher.sql │ └── readme.md ├── partitioning.sql ├── query rettype.py ├── replication.md ├── session.variables.sql ├── table definitions.sql ├── test.prep.II.sql ├── test.prep.sql ├── three utility functions.sql └── Количествено-стойностна сметка │ └── Teams-XI.xlsx ├── parameterization ├── in_list.ora.pls ├── parameterization.sql └── readme.md └── presentations ├── jwtfunc.sql └── recursive queries.pdf /Expected results.pdf: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/stefanov-sm/Database-XI/3d4c68199bb9cf0bee3567f51180b3834996a164/Expected results.pdf -------------------------------------------------------------------------------- /Handling NULL.md: -------------------------------------------------------------------------------- 1 | ```sql 2 | create temporary table a_table (id integer, address text); 3 | insert into a_table 4 | values 5 | (1, 'Студентски Комплекс, ул. „Росарио“ 1, 1756 София'), 6 | (2, 'кв. Дианабад.19 Г, 1172 София'), 7 | (3, '4000 Пловдив Център, ул. „Иван Вазов“ 59'), 8 | (4, 'ж.к. Лозенец, бул. „Джеймс Баучер“ 5, 1164 София'), 9 | (5, 'nowhere'), 10 | (6, null); 11 | ``` 12 | My empyrical mnemonic rule: 13 | Say "don't know" instead of "null" so that your common sense logic works correctly 14 | 15 | An expression with NULL in it returns NULL 16 | except `TRUE OR NULL` and `FALSE AND NULL` 17 | ```sql 18 | select 12 + null, 33 * 2 / null, 19 | false or null, true and null, 20 | true or null, false and null; 21 | ``` 22 | #### Use of `IS NULL` and `IS NOT NULL` unary postfix operators 23 | ```sql 24 | select id, address from a_table 25 | where address is null; 26 | ``` 27 | Using the `IS NULL` operator returns the correct result 28 | Using the equality check operator (=) WHERE ADDRESS = NULL returns no results 29 | Comparison operators do not work properly with NULL 30 | `IS DISTINCT FROM` / `IS NOT DISTINCT FROM` operators work correctly with NULL. 31 | 32 | > [!IMPORTANT] 33 | > Beware: Opposite expressions yield the same result 34 | > and have a good look at [this](https://wiki.postgresql.org/wiki/Don%27t_Do_This#SQL_constructs) article 35 | ```sql 36 | select id, 37 | address > 'к' as res_a, 38 | NOT address > 'к' as res_b 39 | from a_table; 40 | 41 | select id, 42 | coalesce((address > 'к'), false) as res_a, 43 | coalesce(NOT (address > 'к'), false) as res_b 44 | from a_table; 45 | ``` 46 | #### Use of `COALESCE` and `NULLIF` 47 | ```sql 48 | select id, coalesce(address, '*** Безмислени данни ***') as address from a_table; 49 | select id, nullif(address, 'nowhere') as address from a_table; 50 | 51 | discard all; -- this would drop temporary objects 52 | -------------------------------------------------------------------------------- /Links of interest.md: -------------------------------------------------------------------------------- 1 | ### Links that may be of interest 2 | - [Modern SQL](https://www.slideshare.net/slideshow/modern-sql/44086611) in Open Source and Commercial Databases 3 | - [ERD](https://www.visual-paradigm.com/guide/data-modeling/what-is-entity-relationship-diagram/) (entity-relational diagram) 4 | - (not so) [Boring sql](https://notso.boringsql.com/) to showcase the immense power of SQL 5 | - [JSON Schema validation](https://sqlfordevs.com/json-schema-validation) for columns (MySQL and PostgreSQL) and fine [tips](https://sqlfordevs.com/tips) by the same author 6 | - Build SQL-only web apps and services with [SQLPage](https://sql.datapage.app/) 7 | - PostgreSQL 17 [Released](https://www.postgresql.org/about/news/postgresql-17-released-2936/) 8 | - [Stop using SERIAL in Postgres](https://www.naiyerasif.com/post/2024/09/04/stop-using-serial-in-postgres/). Use [identity](https://www.postgresql.org/docs/current/ddl-identity-columns.html) 9 | - Are You Qualified To [Use Null in SQL?](https://agentm.github.io/project-m36/posts/2024-07-16-are-you-qualified-to-use-null.html) quiz 10 | - Transform PostgreSQL into a [Columnar Database](https://stormatics.tech/semabs-planet-postgresql/transform-postgresql-into-a-columnar-database-using-citus) Using Citus 11 | - How to [Delete](https://sqlfordevs.com/delete-duplicate-rows) Duplicate Rows and much more on [SQLforDevs](https://sqlfordevs.com/tips) 12 | - [Convert JSON into Columns and Rows](https://www.crunchydata.com/blog/easily-convert-json-into-columns-and-rows-with-json_table) with [JSON_TABLE](https://www.postgresql.org/docs/current/functions-json.html#FUNCTIONS-SQLJSON-TABLE) 13 | - [SQL/JSON](https://www.depesz.com/2024/10/11/sql-json-is-here-kinda-waiting-for-pg-17/) is here 14 | - Oracle PL/SQL vs Postgres PL/pgSQL - [similar and yet different](https://stormatics.tech/blogs/transitioning-from-oracle-to-postgresql-pl-sql-vs-pl-pgsql) 15 | - Very good stuff on [character encodings](https://thebuild.com/blog/2024/10/27/speaking-in-tongues-postgresql-and-character-encodings/), [collations and locales](https://thebuild.com/blog/2024/10/25/postgresql-collations-1-gentlemen-this-is-a-football/) (5 minutes read) 16 | - SMS integration portal [API documentation](https://www.smsapi.bg/docs/#1-introduction) 17 | - Windows `odbc_fdw` and `file_textarray_fdw` foreign data wrappers for [PostgreSQL 17](https://www.postgresonline.com/journal/index.php?/archives/416-PostgreSQL-17-64-bit-for-Windows-FDWs.html) and [older versions](https://www.postgresonline.com/journal/index.php?/categories/85-odbc_fdw) 18 | - [PostgreSQL HTTP client](https://github.com/pramsey/pgsql-http) extension (very powerful, use carefully). Read `pghttp_README.txt` if necessary. 19 | - A [good playground](https://theory.github.io/sqljson/) to develop your [SQL/JSON Path Language](https://www.postgresql.org/docs/current/functions-json.html#FUNCTIONS-SQLJSON-PATH) expressions 20 | - A fine example of [slow asynchronous processing](https://www.crunchydata.com/blog/running-an-async-web-query-queue-with-procedures-and-pg_cron) using the [http extension](https://github.com/pramsey/pgsql-http). No long transactions. Worth to be used as a pattern. 21 | - GeeksForGeeks [top-sql-databases-to-learn](https://www.geeksforgeeks.org/top-sql-databases-to-learn/). Just note how many times _PostgreSQL_ appears in the article. 22 | - Windows binaries of [FDW](https://www.postgresql.org/docs/current/ddl-foreign-data.html)s & extensions [here](https://www.postgresonline.com/winextensions.php) and [here](https://www.postgresonline.com/journal/index.php?/categories/47-postgresql-versions) 23 | - On [Listen/Notify](https://www.postgresql.org/docs/current/sql-notify.html) and [Python](https://stackoverflow.com/questions/69246880/notifications-in-postgresql-with-pythonpsycopg2-does-not-work) 24 | - Good read and comments on [Life Altering Postgresql Patterns](https://mccue.dev/pages/3-11-25-life-altering-postgresql-patterns) 25 | - [External file](https://github.com/darold/external_file) access extension in PL/pgSQL 26 | - Insert-only workflow illustration aka [making sausages](https://www.youtube.com/watch?v=KIsISCqecFs) (sec. 5 to 30) 27 | - A good read on [Postgres Partitioning Best Practices](https://karenjex.blogspot.com/2025/06/postgres-partitioning-best-practices.html) 28 | - Logical Replication in PostgreSQL [step-by-step guide](https://boringsql.com/posts/logication-replication-introduction/) 29 | 30 | ... and more to come 31 | -------------------------------------------------------------------------------- /Normalization and design/Anomalies in DBMS.pdf: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/stefanov-sm/Database-XI/3d4c68199bb9cf0bee3567f51180b3834996a164/Normalization and design/Anomalies in DBMS.pdf -------------------------------------------------------------------------------- /Normalization and design/Oracle DMRDD.pdf: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/stefanov-sm/Database-XI/3d4c68199bb9cf0bee3567f51180b3834996a164/Normalization and design/Oracle DMRDD.pdf -------------------------------------------------------------------------------- /Normalization and design/Oracle Normalization.pdf: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/stefanov-sm/Database-XI/3d4c68199bb9cf0bee3567f51180b3834996a164/Normalization and design/Oracle Normalization.pdf -------------------------------------------------------------------------------- /Normalization and design/README.md: -------------------------------------------------------------------------------- 1 | ### Good stuff on database design and normalization. 2 | Have a look at [Database Normalization – 1NF 2NF 3NF Table Examples](https://www.freecodecamp.org/news/database-normalization-1nf-2nf-3nf-table-examples/) 3 | or [Database Normalization — How it Works](https://chasegrainger.medium.com/database-normalization-how-it-works-51f79d802042) 4 | -------------------------------------------------------------------------------- /Old-school SQL syntax.md: -------------------------------------------------------------------------------- 1 | ### VERY BASIC SQL SYNTAX 2 | ```SQL 3 | ::= +|-|*|/|=|<>|>|>=|<|<=| || |AND|OR|NOT|IS [NOT] NULL|IS [NOT] DISTINCT FROM|IN|BETWEEN|CASE ;Among others 4 | 5 | ::= 6 | SELECT [[AS] ] [, [[AS] ]]* 7 | [FROM [[AS] ]] 8 | [WHERE ] 9 | [GROUP BY [, ]* [HAVING ]] 10 | [ORDER BY [, ]*] 11 | 12 | ::= ;At least for now 13 | ::= [ASC|DESC] [NULLS FIRST|NULLS LAST] 14 | 15 | ::= 16 | INSERT INTO [()] 17 | VALUES () [, ()]* 18 | 19 | ::= 20 | DELETE FROM [WHERE ] 21 | 22 | ::= 23 | UPDATE SET = [, = ]* 24 | [WHERE ] 25 | 26 | ::= 27 | TRUNCATE TABLE 28 | 29 | ::= |[ ]* 30 | -------------------------------------------------------------------------------- /On-the-board/2024-09-26.sql: -------------------------------------------------------------------------------- 1 | -- 3.5 2 | select * from categories c; 3 | select category_id, category_name from categories c 4 | 5 | where category_name = 'Seafood' or description = 'Cheeses'; 6 | select * from customers c2; 7 | 8 | select customer_name as "Name", 'the city of ' || city as "Борислава" from customers c2 9 | where country = 'USA' order by "Борислава" desc, "Name" desc; 10 | 11 | select country, count (*) as cnt from customers c group by country order by cnt desc; 12 | select * from products p; 13 | 14 | select product_name, price / 1.956 as "Price in EUR" from products p 15 | where price > 100; 16 | 17 | 18 | -- 4.1 19 | select * from categories; 20 | select 'Food class: ' || category_name as "Name ""as is"" !", description from categories 21 | where category_name = 'Seafood'; 22 | 23 | select * from customers; 24 | select customer_name, 'City of ' || city as "City",'Resident of: '|| country as "Residence" 25 | from customers 26 | where country = 'USA' 27 | order by city desc, customer_name desc; 28 | 29 | select * from products 30 | where price >= 20; 31 | 32 | select * -- products.product_name, products.unit, products.price, categories.category_name, categories.description 33 | from products 34 | join categories on products.category_id = categories.category_id; 35 | 36 | 37 | -- 3.4 38 | select *,customer_name,'the city of ' || city as "City ""as is""" 39 | from customers 40 | where country = 'USA' 41 | order by "City ""as is""", customer_name ; 42 | 43 | update customers set postal_code = '999999', address = null 44 | where city = 'Portland'; 45 | 46 | select * from customers 47 | where address is null; 48 | 49 | begin transaction; 50 | 51 | delete from customers 52 | where address is null; 53 | 54 | rollback; 55 | commit; 56 | -------------------------------------------------------------------------------- /On-the-board/2024-10-01.sql: -------------------------------------------------------------------------------- 1 | select * from about_joins.ingredient i 2 | join about_joins.taste t 3 | on i.taste_id = t.id 4 | join about_joins.intensity i2 5 | on i.intensity_id =i2.id; 6 | 7 | select 8 | i.id, i.name as "Име", c.name as "Цвят", 9 | cat.name as "Тип продукт", t.name as "Вкус", 10 | it.intensity as "Сила на вкуса", u.name as "Мярка" 11 | from about_joins.ingredient i 12 | left outer join about_joins.color as c 13 | on c.id = i.color_id 14 | left outer join about_joins.category as cat 15 | on cat.id = i.category_id 16 | left outer join about_joins.taste as t 17 | on t.id = i.taste_id 18 | left outer join about_joins.intensity as it 19 | on it.id = i.intensity_id 20 | left outer join about_joins.unit as u 21 | on u.id = i.unit_id; 22 | 23 | -- Данни за ястие 24 | insert into about_joins.dish_recipe values (5,'таратор','Направете го внимателно', 'сервира се студен'); 25 | 26 | 27 | -- Данни за продукти и количества, bridge table recipe_ingredient 28 | insert into about_joins.recipe_ingredient 29 | values 30 | (5,10,1), -- краставица 31 | (5,9,1), -- кисело мляко 32 | (5,8,30), -- олио 33 | (5,4,100), -- орехи 34 | (5,3,0.25,'Внимавай да не прекалиш'); -- чесън 35 | 36 | 37 | -- Рецептата, с връзка "много към много" чрез bridge table recipe_ingredient 38 | select dr.name, dr.instructions, i.name, ri.quantity, u.name 39 | from about_joins.dish_recipe dr 40 | join about_joins.recipe_ingredient ri 41 | on dr.id=ri.dish_id 42 | join about_joins.ingredient i 43 | on i.id=ri.ingredient_id 44 | join about_joins.unit u 45 | on i.unit_id =u.id; 46 | -------------------------------------------------------------------------------- /On-the-board/2024-10-10.sql: -------------------------------------------------------------------------------- 1 | -- Views, CTEs and conditional expressions 2 | 3 | -- Using subqueries (table-valued and scalar) 4 | select "млечни продукти", "мерна единица","цена", 5 | "цена"/(select avg(price)::numeric(20,2)from public.products) as "скъпо ли е" 6 | from ( 7 | select * from 8 | ( 9 | select product_id, product_name as "млечни продукти", unit as "мерна единица", 10 | price as "цена", category_id as "категория" 11 | from (select * from public.products) as p 12 | where category_id = 4 13 | ) as daip 14 | join (select * from public.categories) as c on c.category_id = daip."категория" 15 | ) as q 16 | order by "млечни продукти" desc 17 | limit 4; 18 | 19 | -- Using a view 20 | create or replace view about_joins.delme_v as 21 | select * from 22 | ( 23 | select product_id, product_name as "млечни продукти", unit as "мерна единица", 24 | price as "цена", category_id as "категория" 25 | from (select * from public.products) as p 26 | where category_id = 4 27 | ) as daip 28 | join (select * from public.categories) as c on c.category_id = daip."категория"; 29 | 30 | select "млечни продукти", "мерна единица","цена", 31 | "цена"/(select avg(price)::numeric(20,2)from public.products) as "скъпо ли е" 32 | from about_joins.delme_v as q 33 | order by "млечни продукти" desc 34 | limit 4; 35 | 36 | 37 | -- Using CTE (non-recursive). WITH clause 38 | with cte_t as ( 39 | select * from 40 | ( 41 | select product_id, product_name as "млечни продукти", unit as "мерна единица", 42 | price as "цена", category_id as "категория" 43 | from (select * from public.products) as p 44 | where category_id = 4 45 | ) as daip 46 | join (select * from public.categories) as c on c.category_id = daip."категория" 47 | ), 48 | avp(p, s) as ( 49 | select avg(price)::numeric(20,2) as invisible, 3 as stupid from public.products 50 | ) 51 | --select * from avp; 52 | select "млечни продукти", "мерна единица","цена", 53 | "цена"/(select p from avp) as "скъпо ли е" 54 | from cte_t as q 55 | order by "млечни продукти" desc 56 | limit 4; 57 | 58 | 59 | -- Conditional expressions (CASE) 60 | 61 | -- Calculated CASE 62 | SELECT CASE 63 | when 3 > 4 64 | then 'red' 65 | when 4 > 4 66 | then 'blue' 67 | else 'green' 68 | END; 69 | 70 | -- Simple CASE 71 | SELECT CASE 3 72 | when 4 73 | then 'red' 74 | when 5 75 | then 'blue' 76 | when 3 77 | then 'white' 78 | else 'green' 79 | END; 80 | 81 | -------------------------------------------------------------------------------- /On-the-board/2024-11-07.sql: -------------------------------------------------------------------------------- 1 | create table bigtablea 2 | ( 3 | id serial primary key not null, 4 | value numeric, 5 | roman text 6 | ); 7 | 8 | insert into bigtablea (value, roman) 9 | select (random() * 100000)::numeric(10, 2), 10 | to_char((random() * 3000)::integer, 'FMRN') 11 | from generate_series(1, 10000000, 1) as s; 12 | 13 | select * from bigtablea; 14 | 15 | create table bigtableb as select * from bigtablea; 16 | 17 | -- Create discrepancies 18 | update bigtablea set value = 7301.39, roman = 'MXMII' where id = 10; 19 | update bigtablea set value = 79320.19, roman = 'XIMLC' where id = 15; 20 | update bigtablea set value = 23150.07, roman = 'CILXM' where id = 350; 21 | update bigtableb set value = 41223.60, roman = 'ILMCC' where id = 1001; 22 | update bigtableb set value = 86201.90, roman = 'MXMII' where id = 2001; 23 | update bigtableb set value = 85710.00, roman = 'CCXMX' where id = 2090; 24 | 25 | -- Find discrepancies 26 | select * from ( 27 | ( 28 | select *, 'tableA' as "comes from" from bigtablea 29 | except all 30 | select *, 'tableA' as "comes from" from bigtableb 31 | ) 32 | union all 33 | ( 34 | select *, 'tableB' as "comes from" from bigtableb 35 | except all 36 | select *, 'tableB' as "comes from" from bigtablea 37 | ) 38 | ) 39 | order by id, "comes from"; 40 | -------------------------------------------------------------------------------- /On-the-board/2024-11-14.sql: -------------------------------------------------------------------------------- 1 | -- Time - dependant (temporal) data 2 | create schema temporal; 3 | 4 | create table temporal.goods ( 5 | id serial primary key not null, 6 | goods_name text not null, 7 | price numeric 8 | ); 9 | 10 | insert into temporal.goods (goods_name,price) values 11 | ('домати', 4.8), 12 | ('краставици', 3.5), 13 | ('олио', 3.9), 14 | ('брашно', 2.5), 15 | ('лук', 1.3); 16 | 17 | select * from temporal.goods; 18 | select price from temporal.goods where id = 4; 19 | 20 | create table temporal.price_temporal ( 21 | goods_id integer references temporal.goods(id), 22 | valid_from date not null, 23 | valid_to date, 24 | price numeric 25 | ); 26 | 27 | insert into temporal.price_temporal values 28 | (4,'2024-04-14','2024-06-19', 2.5), 29 | (4,'2024-11-11', null, 5.0); -- not known until when 30 | 31 | -- An almost idiomatic query 32 | -- current_date as a parameter 33 | select coalesce(t.price, g.price) 34 | from temporal.goods as g 35 | left outer join temporal.price_temporal as t 36 | on g.id = t.goods_id 37 | -- the temporal dependancy follows 38 | and current_date between 39 | valid_from and coalesce(valid_to, 'infinity') 40 | where g.id = 4; 41 | 42 | -- Cleanup 43 | DROP SCHEMA temporal CASCADE; 44 | -------------------------------------------------------------------------------- /On-the-board/2024-12-05.sql: -------------------------------------------------------------------------------- 1 | -- drop table if exists public.iban_sizes; 2 | create table public.iban_sizes ( 3 | country_abbrev text primary key, 4 | iban_size integer check (iban_size between 10 and 50), 5 | notes text 6 | ); 7 | insert into public.iban_sizes (iban_size, country_abbrev, notes) values 8 | ('28', 'AL', 'Albania'),('24', 'AD', 'Andorra'),('20', 'AT', 'Austria'),('28', 'AZ', 'Azerbaijan'),('22', 'BH', 'Bahrain'), 9 | ('28', 'BY', 'Belarus'),('16', 'BE', 'Belgium'),('20', 'BA', 'Bosnia and Herzegovina'),('29', 'BR', 'Brazil'),('22', 'BG', 'Bulgaria'), 10 | ('27', 'BI', 'Burundi'),('22', 'CR', 'Costa Rica'),('21', 'HR', 'Croatia'),('28', 'CY', 'Cyprus'),('24', 'CZ', 'Czech Republic'), 11 | ('18', 'DK', 'Denmark'),('27', 'DJ', 'Djibouti'),('28', 'DO', 'Dominican Republic'),('23', 'TL', 'East Timor'),('29', 'EG', 'Egypt'), 12 | ('28', 'SV', 'El Salvador'),('20', 'EE', 'Estonia'),('18', 'FK', 'Falkland Islands'),('18', 'FO', 'Faroe Islands'),('18', 'FI', 'Finland'), 13 | ('27', 'FR', 'France'),('22', 'GE', 'Georgia'),('22', 'DE', 'Germany'),('23', 'GI', 'Gibraltar'),('27', 'GR', 'Greece'), 14 | ('18', 'GL', 'Greenland'),('28', 'GT', 'Guatemala'),('28', 'HU', 'Hungary'),('26', 'IS', 'Iceland'),('23', 'IQ', 'Iraq'), 15 | ('22', 'IE', 'Ireland'),('23', 'IL', 'Israel'),('27', 'IT', 'Italy'),('30', 'JO', 'Jordan'),('20', 'KZ', 'Kazakhstan'), 16 | ('20', 'XK', 'Kosovo'),('30', 'KW', 'Kuwait'),('21', 'LV', 'Latvia'),('28', 'LB', 'Lebanon'),('25', 'LY', 'Libya'), 17 | ('21', 'LI', 'Liechtenstein'),('20', 'LT', 'Lithuania'),('20', 'LU', 'Luxembourg'),('31', 'MT', 'Malta'),('27', 'MR', 'Mauritania'), 18 | ('30', 'MU', 'Mauritius'),('27', 'MC', 'Monaco'),('24', 'MD', 'Moldova'),('20', 'MN', 'Mongolia'),('22', 'ME', 'Montenegro'), 19 | ('18', 'NL', 'Netherlands'),('28', 'NI', 'Nicaragua'),('19', 'MK', 'North Macedonia'),('15', 'NO', 'Norway'),('23', 'OM', 'Oman'), 20 | ('24', 'PK', 'Pakistan'),('29', 'PS', 'Palestinian territories'),('28', 'PL', 'Poland'),('25', 'PT', 'Portugal'),('29', 'QA', 'Qatar'), 21 | ('24', 'RO', 'Romania'),('33', 'RU', 'Russia'),('32', 'LC', 'Saint Lucia'),('27', 'SM', 'San Marino'),('25', 'ST', 'Sao Tome and Principe'), 22 | ('24', 'SA', 'Saudi Arabia'),('22', 'RS', 'Serbia'),('31', 'SC', 'Seychelles'),('24', 'SK', 'Slovakia'),('19', 'SI', 'Slovenia'), 23 | ('23', 'SO', 'Somalia'),('24', 'ES', 'Spain'),('18', 'SD', 'Sudan'),('24', 'SE', 'Sweden'),('21', 'CH', 'Switzerland'), 24 | ('24', 'TN', 'Tunisia'),('26', 'TR', 'Turkey'),('29', 'UA', 'Ukraine'),('23', 'AE', 'United Arab Emirates'),('22', 'GB', 'United Kingdom'), 25 | ('22', 'VA', 'Vatican City'),('24', 'VG', 'Virgin Islands, British'),('30', 'YE', 'Yemen'); 26 | select * from public.iban_sizes; 27 | 28 | -- Клас Б 29 | create or replace function public.iban_check (arg_iban text) 30 | returns boolean language plpgsql immutable as 31 | $$ 32 | declare 33 | country_id text; 34 | iban_arr text[]; 35 | letters text[] := '{A,B,C,D,E,F,G,H,I,J,K,L,M,N,O,P,Q,R,S,T,U,V,W,X,Y,Z}'; 36 | begin 37 | arg_iban := regexp_replace(upper(arg_iban), '[^A-Z0-9]', '', 'g'); 38 | country_id := substr(arg_iban, 1, 2); 39 | if not exists ( 40 | select from public.iban_sizes 41 | where country_abbrev = country_id 42 | and length(arg_iban) = iban_size 43 | ) then 44 | return false; 45 | end if; 46 | arg_iban := substr(arg_iban, 5) || left(arg_iban, 4); 47 | iban_arr := string_to_array(arg_iban, null); 48 | for i in 1 .. array_length(iban_arr, 1) loop 49 | if not iban_arr[i] between '0' and '9' then 50 | iban_arr[i] := (array_position(letters, iban_arr[i]) + 9)::text; 51 | -- or iban_arr[i] := (select o + 9 from unnest(letters) with ordinality as u(l, o) where l = iban_arr[i])::text; 52 | -- which is in fact an implementation of array_position 53 | end if; 54 | end loop; 55 | arg_iban := array_to_string(iban_arr, ''); 56 | -- raise notice '%', arg_iban; 57 | return (arg_iban::numeric % 97) = 1; 58 | end; 59 | $$; 60 | 61 | -- Клас В 62 | create or replace function public.iban_valid(arg_iban text) 63 | returns boolean language plpgsql immutable as 64 | $$ 65 | declare 66 | letters text[] := '{A,B,C,D,E,F,G,H,I,J,K,L,M,N,O,P,Q,R,S,T,U,V,W,X,Y,Z}'; 67 | arr_iban text[]; 68 | i integer; 69 | mod_result integer; 70 | begin 71 | arg_iban := upper(arg_iban); 72 | arg_iban := regexp_replace(arg_iban, '[^A-Z0-9]', '', 'g'); 73 | if not exists ( 74 | select 1 from iban_sizes where country_abbrev = substr(arg_iban, 1, 2) 75 | and length(arg_iban) = iban_size 76 | ) then 77 | return false; 78 | end if; 79 | arg_iban := substring(arg_iban from 5) || left(arg_iban, 4); 80 | arr_iban := string_to_array(arg_iban, null); 81 | for i in 1 .. array_length(arr_iban, 1) loop 82 | if arr_iban[i] between 'A' and 'Z' then 83 | arr_iban[i] := (array_position(letters, arr_iban[i]) + 9)::text; 84 | end if; 85 | end loop; 86 | arg_iban = array_to_string(arr_iban, ''); 87 | mod_result := arg_iban :: numeric % 97; 88 | 89 | raise notice '%', arg_iban; 90 | return mod_result = 1; 91 | end; 92 | $$; 93 | 94 | select public.iban_valid('GB82 WEST 1234 5698 7654 32'); 95 | 96 | -- Клас А 97 | -- Coming soon 98 | -------------------------------------------------------------------------------- /On-the-board/2024-12-17.sql: -------------------------------------------------------------------------------- 1 | ----------------------------------------------------------------------------------- 2 | -- JSON generating queries 3 | ----------------------------------------------------------------------------------- 4 | 5 | CREATE TEMPORARY TABLE actions ( 6 | action_time timestamp without time zone, 7 | user_id integer 8 | ); 9 | 10 | INSERT INTO actions (action_time, user_id) VALUES 11 | ('2015-01-20 01:00:00', 1), 12 | ('2015-01-01 01:00:00', 1), 13 | ('2015-01-10 01:00:00', 1), 14 | ('2015-01-12 01:00:00', 1), 15 | ('2015-01-16 01:00:00', 1), 16 | ('2015-01-23 01:00:00', 1), 17 | ('2015-02-20 01:00:00', 1), 18 | ('2015-03-20 01:00:00', 1), 19 | ('2015-05-20 01:00:00', 1), 20 | ('2015-06-20 01:00:00', 1), 21 | ('2015-01-20 01:00:00', 2), 22 | ('2015-03-20 01:00:00', 2), 23 | ('2015-04-20 01:00:00', 2), 24 | ('2015-05-20 01:00:00', 2), 25 | ('2015-05-21 01:00:00', 2), 26 | ('2015-05-21 01:00:00', 2), 27 | ('2015-05-23 01:00:00', 2); 28 | 29 | ----------------------------------------------------------------------------------- 30 | -- table-returning query 31 | select json_agg(to_json(t)) from ( 32 | 33 | -- the table-returning query here with no trailing semicolon 34 | select action_time, substr(random()::text,3,7) as action_rndm from actions where user_id = 2 35 | 36 | ) as t; 37 | 38 | ----------------------------------------------------------------------------------- 39 | -- scalar query 40 | select json_build_object('value', ( 41 | 42 | -- the scalar query here with no trailing semicolon 43 | 44 | select max(action_time) from actions where user_id = 2 45 | 46 | )); 47 | 48 | ----------------------------------------------------------------------------------- 49 | -- table-returning query in a CTE 50 | with t as ( 51 | 52 | -- the table-returning query here with no trailing semicolon 53 | 54 | select action_time, substr(random()::text,3,7) as action_rndm 55 | from actions 56 | where user_id = 2 57 | 58 | ) 59 | select json_agg(to_json(t)) from t; 60 | 61 | ----------------------------------------------------------------------------------- 62 | -- table-returning DML query in a data modifying CTE 63 | with t as ( 64 | 65 | -- the table-returning DML query (using RETURNING) 66 | insert into actions (action_time, user_id) 67 | select clock_timestamp(), 5 from generate_series(1, 10) 68 | RETURNING to_char(action_time, 'yyyy-mm-dd hh24:mi:ss.us') as action_time 69 | 70 | ) 71 | select json_agg(to_json(t)) from t; 72 | 73 | 74 | ----------------------------------------------------------------------------------- 75 | -- JSON flattening to regular tables 76 | ----------------------------------------------------------------------------------- 77 | 78 | create temporary table a_table (id integer, jsondata jsonb); 79 | insert into a_table values 80 | (1, '{"List":[{"One": 1, "Two": true, "Three": "3"}, {"One": 11, "Two": false, "Three": "13", "Four": {"Five": 5}}, {"One": 21, "Two": null, "Three": "23"}]}'::jsonb), 81 | (2, '{"List":[{"One": 101, "Two": true, "Three": "103"}, {"One": 1011, "Two": false, "Three": "1013"}, {"One": 1021, "Two": null, "Three": "1023"}]}'), 82 | (3, '{"List":[{"One": 201, "Two": true, "Three": "203"}, {"One": 2011, "Two": false, "Three": "2013"}, {"One": 2021, "Two": true, "Three": "2023"}]}'); 83 | 84 | create temporary table b_table (id integer, jsondata jsonb); 85 | insert into b_table values 86 | (1, '{"One": 1, "Two": true, "Three": "3"}'::jsonb), 87 | (2, '{"One": 1011, "Two": false, "Three": "1013", "Four": {"Five": 5}}'), 88 | (3, '{"One": 0, "Four": 4}'); 89 | 90 | ----------------------------------------------------------------------------------- 91 | 92 | select id, 93 | (j['One'])::text one, 94 | (j->>'Two')::boolean two, 95 | (j->>'Three')::integer three, 96 | (j->'Four'->>'Five')::integer four 97 | from a_table, 98 | lateral jsonb_array_elements(jsondata->'List') as j; 99 | 100 | ----------------------------------------------------------------------------------- 101 | 102 | select id, "One", "Two", "Three", ("Four"->>'Five')::integer four 103 | from a_table, 104 | lateral jsonb_to_recordset(jsondata->'List') 105 | as j ("One" text, "Two" boolean, "Three" integer, "Four" jsonb); 106 | 107 | ----------------------------------------------------------------------------------- 108 | 109 | select id, 110 | (jsondata->>'One') one, 111 | (jsondata->>'Two')::boolean two, 112 | (jsondata->>'Three')::integer three, 113 | (jsondata->'Four'->>'Five')::integer four 114 | from b_table; 115 | 116 | ----------------------------------------------------------------------------------- 117 | 118 | discard all; 119 | -------------------------------------------------------------------------------- /On-the-board/2024-12-19.sql: -------------------------------------------------------------------------------- 1 | -- SQL Server style concat operator 2 | create or replace function custom_cat_handler(l text, r text) 3 | returns text language sql parallel safe immutable strict as 4 | $$ 5 | select l || r; 6 | $$; 7 | create operator + (leftarg = text, rightarg = text, function = custom_cat_handler); 8 | select 'Hello' + ' World!'; 9 | 10 | -- Parallel resistors operator 11 | ------------------------------------------------------ 12 | create function custom_parallel(l numeric , r numeric) 13 | returns numeric language sql parallel safe immutable strict as 14 | $$ 15 | select l*r/(l+r) 16 | $$; 17 | create operator || (leftarg = numeric, rightarg = numeric, function = custom_parallel); 18 | select 10 || 20; 19 | 20 | -- Cleanup 21 | drop operator || (numeric, numeric); 22 | drop function custom_parallel; 23 | 24 | -- Complex number type (called jtype) 25 | ------------------------------------------------------ 26 | create type jtype as (r numeric, i numeric); 27 | select (1,2)::jtype; 28 | 29 | create function jtype_add(l jtype, r jtype) 30 | returns jtype language sql parallel safe immutable strict as 31 | $$ 32 | select (l.r + r.r, l.i + r.i)::jtype; 33 | $$; 34 | create operator + (leftarg = jtype, rightarg = jtype,function = jtype_add); 35 | 36 | select (1,2)::jtype + (3,4)::jtype; 37 | 38 | -- 39 | 40 | create function jtype_mul(l jtype, r jtype) 41 | returns jtype language sql parallel safe immutable strict as 42 | $$ 43 | select (l.r * r.r - l.i * r.i, l.r * r.i + l.i * r.r)::jtype; 44 | $$; 45 | create operator * (leftarg = jtype, rightarg = jtype,function = jtype_mul); 46 | 47 | select (1,2)::jtype * (3,4)::jtype; 48 | 49 | -- Casting a numeric to jtype with 0i 50 | ------------------------------------------------------ 51 | create function num_to_jtype (l numeric) returns jtype 52 | language sql immutable as 53 | $$ 54 | select (l, 0)::jtype; 55 | $$; 56 | 57 | create cast (numeric as jtype) with function num_to_jtype; 58 | select 3::numeric::jtype; 59 | -------------------------------------------------------------------------------- /On-the-board/2025-01-07.sql: -------------------------------------------------------------------------------- 1 | drop table if exists dropme; 2 | create table dropme (num1 numeric, num2 numeric, t1 text); 3 | insert into dropme values(10, 20, 'dog'), (15, 25, 'cat'), (19, 21, 'rabbit'); 4 | select * from dropme; 5 | 6 | ------------------------------------ 7 | -- A trigger to skip trivial updates 8 | 9 | create or replace function no_trivial_update() 10 | returns trigger language plpgsql as 11 | $$ 12 | begin 13 | raise notice 'Trigger fired'; 14 | if to_jsonb(new) = to_jsonb(old) then 15 | raise notice 'NULL returned'; 16 | return null; 17 | else 18 | raise notice 'NEW returned'; 19 | return new; 20 | end if; 21 | end; 22 | $$; 23 | 24 | create or replace trigger bt_u 25 | before update on dropme for each row 26 | execute function no_trivial_update(); 27 | 28 | update dropme set t1 = 'dog' where num1 = 10; 29 | update dropme set t1 = 'Dog' where num1 = 10; 30 | drop trigger bt_u on dropme; 31 | 32 | ------------------------------ 33 | -- A trigger to disable DELETE 34 | 35 | create or replace function no_delete() 36 | returns trigger language plpgsql as 37 | $$ 38 | begin 39 | return null; 40 | end; 41 | $$; 42 | 43 | create or replace trigger bt_d 44 | before delete on dropme for each row 45 | execute function no_delete(); 46 | 47 | delete from dropme where num1 = 10; 48 | drop trigger bt_d on dropme; 49 | drop table if exists dropme; 50 | -------------------------------------------------------------------------------- /On-the-board/2025-01-09.sql: -------------------------------------------------------------------------------- 1 | -- Implicit cursor in PL/pgSQL 2 | -- Using a generic record 3 | create or replace function pg_temp.f1() 4 | returns numeric language plpgsql as 5 | $$ 6 | declare 7 | ret_val numeric := 0; 8 | r record; 9 | begin 10 | for r in select * from temporal.goods loop 11 | ret_val := ret_val + r.price; 12 | raise notice '%', r.goods_name; 13 | end loop; 14 | return ret_val; 15 | end; 16 | $$; 17 | 18 | -- Using separate variables 19 | create or replace function pg_temp.f2() 20 | returns numeric language plpgsql as 21 | $$ 22 | declare 23 | ret_val numeric := 0; 24 | var_price numeric; 25 | var_name text; 26 | begin 27 | for var_price, var_name in select price, goods_name from temporal.goods loop 28 | ret_val := ret_val + var_price; 29 | raise notice '%', var_name; 30 | end loop; 31 | return ret_val; 32 | end; 33 | $$; 34 | 35 | -- Data-modifying CTE. Very powerful and useful 36 | -- https://www.postgresql.org/docs/current/queries-with.html#QUERIES-WITH-MODIFYING 37 | with t as ( 38 | update temporal.goods 39 | set goods_name = 'лук' 40 | where goods_name ~* 'onion' -- whatever DML query 41 | returning id -- or whatever list of expressions 42 | ) 43 | select string_agg(id::text, ',') from t; -- may be as complex as it takes 44 | -------------------------------------------------------------------------------- /On-the-board/2025-01-14.sql: -------------------------------------------------------------------------------- 1 | -- MySQL group_concat aggregate implementation in PostgreSQL 2 | -- for compatibility purposes 3 | 4 | create or replace function concatf(container text[], runningValue text) 5 | returns text[] language sql as 6 | $$ 7 | select case 8 | when runningValue is null then container 9 | when container is null then array[runningValue] 10 | else container || runningValue -- equiv. to array_append(container, runningValue) 11 | end; 12 | $$; 13 | 14 | create or replace function concatr(container text[]) 15 | returns text language sql as 16 | $$ 17 | select array_to_string(container, ',') 18 | $$; 19 | 20 | create or replace aggregate group_concat(text) 21 | ( 22 | STYPE = text[], 23 | SFUNC = concatf, 24 | FINALFUNC = concatr 25 | ); 26 | 27 | -- Demo 28 | 29 | create temporary table Tempp ( 30 | s text 31 | ); 32 | insert into Tempp values ('sharo'), ('drugo kuche'), ('magu'); 33 | select group_concat(s) from Tempp; 34 | 35 | 36 | -- or a bit more more generic, note the anyelement pseudotype 37 | 38 | create or replace function group_concat_f(container text[], runningValue anyelement) 39 | returns text[] language sql as 40 | $$ 41 | select case 42 | when runningValue is null then container 43 | when container is null then array[runningValue::text] 44 | else container || runningValue::text 45 | end; 46 | $$; 47 | 48 | create or replace aggregate group_concat(anyelement) 49 | ( 50 | STYPE = text[], 51 | SFUNC = group_concat_f, 52 | FINALFUNC = concatr 53 | ); 54 | -------------------------------------------------------------------------------- /On-the-board/2025-01-21.md: -------------------------------------------------------------------------------- 1 | #### Reverse Polish Notation (RPN) 2 | 3 | The procedure used to execute RPN using a [stack machine](https://en.wikipedia.org/wiki/Stack_machine) is as follows: 4 | - Expressions are executed left to right; 5 | - Each time a number or operand is read, we push it to the stack; 6 | - Each time an operator comes up, we pop the required operands from the stack, perform the operations, and push the result back to the stack; 7 | - Finished when there are no tokens (numbers, operators, or any other mathematical symbol) to read. The final number on the stack is the result. 8 |

9 | 10 | 11 | #### The [Shunting Yard Algorithm](https://en.wikipedia.org/wiki/Shunting_yard_algorithm) by [Edsger Dijkstra](https://en.wikipedia.org/wiki/Edsger_W._Dijkstra) 12 | 13 | Parses infix expressions into RPN 14 | 15 | ![shunting-yard](https://github.com/user-attachments/assets/ee6d48ef-4e6f-4a1b-83be-12f9e6088f44) 16 | 17 | A pseudocode of the algorithm is as follows: 18 | ``` 19 | While there are tokens to be read: 20 | Read a token 21 | If it's a value pass it to the output 22 | If it's an operator: 23 | While there's an operator on the top of the stack with higher precedence: 24 | Pop operators from the stack into the output 25 | Push the current operator onto the stack 26 | If it's a left bracket push it onto the stack 27 | If it's a right bracket: 28 | While there's not a left bracket at the top of the stack: 29 | Pop operators from the stack into the output 30 | Pop the left bracket from the stack and discard it 31 | While there are operators on the stack pop them into the output 32 | ``` 33 | -------------------------------------------------------------------------------- /On-the-board/2025-01-30.sql: -------------------------------------------------------------------------------- 1 | select case when qty < 0 then 0 else qty end as qty 2 | from 3 | ( 4 | select $RAINFALL-(select sum(reading_rainfall) from meteo_readings where reading_time >= current_date - 3) as qty 5 | where (select reading_temp from meteo_readings order by reading_time desc limit 1) between $MIN_TEMP and $MAX_TEMP 6 | and (select reading_illumination from meteo_readings order by reading_time desc limit 1) < $MAX_ILLUMINATION 7 | ) as t; 8 | -------------------------------------------------------------------------------- /On-the-board/2025-02-24.sql: -------------------------------------------------------------------------------- 1 | -- The extension binary is a part of the distribution pack 2 | create extension file_fdw; 3 | create server file_server foreign data wrapper file_fdw; 4 | 5 | -- Attach file eurofxref-hist.csv (ECB exchange rate history) as a foreign table 6 | -- https://www.ecb.europa.eu/stats/eurofxref/eurofxref-hist.zip 7 | -- Fields' list is taken from the CSV file's header 8 | -- Note the trailing dummy field because of the trailing commas in the CSV file 9 | create foreign table ecb_forex 10 | ( 11 | "Date" date, 12 | USD numeric, JPY numeric, BGN numeric, CYP numeric, CZK numeric, DKK numeric, EEK numeric, 13 | GBP numeric, HUF numeric, LTL numeric, LVL numeric, MTL numeric, PLN numeric, ROL numeric, 14 | RON numeric, SEK numeric, SIT numeric, SKK numeric, CHF numeric, ISK numeric, NOK numeric, 15 | HRK numeric, RUB numeric, TRL numeric, TRY numeric, AUD numeric, BRL numeric, CAD numeric, 16 | CNY numeric, HKD numeric, IDR numeric, ILS numeric, INR numeric, KRW numeric, MXN numeric, 17 | MYR numeric, NZD numeric, PHP numeric, SGD numeric, THB numeric, ZAR numeric, dummy text 18 | ) 19 | server file_server 20 | options ( 21 | filename 'C:/foreign_data/eurofxref-hist.csv', 22 | format 'csv', delimiter ',', null 'N/A', header 'true' 23 | ); 24 | 25 | select * from ecb_forex; 26 | 27 | -- Min and max rating of the turkish lira 28 | select * from (select 'try' as currency, "Date", try from ecb_forex order by try limit 1) 29 | union all 30 | select * from (select 'try' as currency, "Date", try from ecb_forex order by try desc nulls last limit 1); 31 | 32 | -- Min and max rating of the turkish lira and swiss frank using window functions 33 | select first_value("Date") over (order by try), first_value(try) over (order by try), 34 | first_value("Date") over (order by try desc nulls last), first_value(try) over (order by try desc nulls last), 35 | first_value("Date") over (order by chf), first_value(chf) over (order by chf), 36 | first_value("Date") over (order by chf desc nulls last), first_value(chf) over (order by chf desc nulls last) 37 | from ecb_forex limit 1; 38 | 39 | -- Unpivot the table into a "thin" one (currency text, currency_date date, value numeric) 40 | create or replace function forex_long() 41 | returns table (currency text, currency_date date, value numeric) language plpgsql stable as 42 | $$ 43 | declare 44 | currency_list text[]; 45 | jsonstruct json; 46 | currency text; 47 | DYNSQL_TEMPLATE constant text := 'SELECT %1$L, "Date", %1$s FROM ecb_forex'; 48 | begin 49 | -- extract the list of columns (reflection-like operation using JSON) 50 | jsonstruct := (select to_json(ef) from ecb_forex ef limit 1); 51 | select array_agg(j) into currency_list from json_object_keys(jsonstruct) as j where j not in ('Date', 'dummy'); 52 | 53 | -- extract data per currency using dynamic SQL 54 | foreach currency in array currency_list loop 55 | return query execute format(DYNSQL_TEMPLATE, currency) using currency; 56 | end loop; 57 | end; 58 | $$; 59 | 60 | select * from forex_long() order by currency; 61 | 62 | -- create a "real" table with a stable structure that can be indexed 63 | create table ecb_forex_thin as select * from forex_long(); 64 | alter table ecb_forex_thin add constraint ecb_forex_thin_pk primary key (currency, currency_date); 65 | -------------------------------------------------------------------------------- /On-the-board/2025-02-26.sql: -------------------------------------------------------------------------------- 1 | -- forex_long() version w/o the use of JSON reflection 2 | -- using the system catalog and an implicit cursor loop 3 | create or replace function forex_long() 4 | returns table (currency text, currency_date date, value numeric) language plpgsql stable as 5 | $$ 6 | declare 7 | currency text; 8 | DYNSQL_TEMPLATE constant text := 'SELECT %1$L, "Date", %1$s FROM ecb_forex'; 9 | begin 10 | for currency in 11 | select column_name from information_schema."columns" c 12 | where table_schema = 'public' 13 | and table_name = 'ecb_forex' 14 | and c.column_name not in ('Date', 'dummy') 15 | loop 16 | return query 17 | execute format(DYNSQL_TEMPLATE, currency) using currency; 18 | end loop; 19 | end; 20 | $$; 21 | 22 | -- version of the foreign table with all row data in a single column 23 | -- tolerant to damaged data files 24 | -- note the BACKSPACE (E'\b') delimiter 25 | create foreign table ecb_forexd 26 | ( 27 | rec text 28 | ) 29 | server file_server 30 | options ( 31 | filename 'C:/foreign_data/eurofxref-hist.csv', 32 | format 'csv', delimiter E'\b', null 'N/A', header 'true' 33 | ); 34 | 35 | -- version of the unpivot function that works with table ecb_forexd 36 | -- note the unnest function with two arguments and the array slice, row_array[2:] 37 | create or replace function thin_out_table() 38 | returns table(currency text, "Date" date, value numeric) language plpgsql as 39 | $$ 40 | declare 41 | r text; 42 | row_array text[]; 43 | columns_list text[] := (select array_agg(column_name) 44 | from information_schema.columns 45 | where table_name = 'ecb_forex' 46 | and table_schema = 'public' 47 | and column_name not in ('Date', 'dummy')); 48 | begin 49 | for r in select rec from ecb_forexd loop 50 | row_array := string_to_array(r, ','); 51 | return query 52 | select curr, row_array[1]::date, NULLIF(NULLIF(rate, 'N/A'), '')::numeric 53 | from unnest(columns_list, row_array[2:]) as t(curr, rate) 54 | where curr is not null and rate is not null; 55 | end loop; 56 | end; 57 | $$; 58 | -------------------------------------------------------------------------------- /On-the-board/2025-03-10.sql: -------------------------------------------------------------------------------- 1 | create or replace function pg_input_is_valid(t text, target_t text) 2 | returns boolean immutable language plpgsql as 3 | $$ 4 | begin 5 | execute format('select %L :: %s', t, taret_t); 6 | -- or 'SELECT cast(%L as %s)' in standard SQL 7 | return true; 8 | exception when others then 9 | return false; 10 | end; 11 | $$; 12 | 13 | select * from pg_input_is_valid('123', 'int'); 14 | select * from pg_input_is_valid('some text', 'int'); 15 | 16 | create type custom_type as (num numeric, t text); 17 | select * from pg_input_is_valid('(123, text)', 'custom_type'); 18 | select * from pg_input_is_valid('(123, "text")', 'custom_type'); 19 | 20 | create or replace function c_random(one numeric, two numeric) 21 | returns numeric volatile language sql as 22 | $$ 23 | select random()*(two - one) + one; 24 | $$; 25 | 26 | create or replace function c_random(one integer, two integer) 27 | returns integer volatile language sql as 28 | $$ 29 | select random()*(two - one) + one; 30 | $$; 31 | 32 | select * from c_random(3.1, 18.2); 33 | select * from c_random(1, 26); 34 | 35 | drop type custom_type; 36 | drop function public.pg_input_is_valid; 37 | drop function c_random(numeric, numeric); 38 | drop function c_random(integer, integer); 39 | 40 | -------------------------------------------------------------------------------- /On-the-board/state-machine/State machine II-2.sql: -------------------------------------------------------------------------------- 1 | create or replace function sm.new_sm_unit (details jsonb, arg_unit_name text) returns integer 2 | language sql 3 | as 4 | $$ 5 | insert into sm.sm_unit(unit_name, unit_details) 6 | values( 7 | arg_unit_name, details 8 | ) 9 | returning id; 10 | $$; 11 | 12 | select sm.new_sm_unit('{"MIF": "AEG washing machine", "SN": "12345", "Customer": "Gergana"}', 'Service call Gergana'); 13 | select sm.new_sm_unit('{"MIF": "Philips Hair dryer", "SN": "54321", "Customer": "Boryana"}', 'Service call Boryana'); 14 | select sm.new_sm_unit('{"MIF": "Plumbing", "Symptom": "leak", "SN": null, "Customer": "Stefan"}', 'Service call Stefan'); 15 | 16 | create or replace function handle_signal(unit_id integer, signal_id integer, details jsonb) returns integer 17 | language plpgsql 18 | as 19 | $$ 20 | begin 21 | -- Implementation here 22 | end; 23 | $$; 24 | 25 | create or replace function unit_status(arg_unit_id integer) returns table (status_id integer, status_name text, details jsonb) 26 | language plpgsql 27 | as 28 | $$ 29 | declare 30 | var_state integer; 31 | var_payload jsonb; 32 | INITIAL_STATE constant integer default 0; 33 | begin 34 | select final_state_id, payload into var_state, var_payload from sm.sm_log 35 | where arg_unit_id=unit_id order by ts desc limit 1; 36 | status_id := COALESCE(var_state, INITIAL_STATE); 37 | status_name := (select state_name from sm.state where id=status_id); 38 | details := COALESCE(var_payload, 39 | ( 40 | select unit_details from sm.sm_unit where id=unit_id 41 | ) 42 | ); 43 | return next; 44 | end; 45 | $$ 46 | 47 | 48 | 49 | 50 | 51 | 52 | create table if not exists sm_log( 53 | unit_id integer, initial_state_id integer, 54 | final_state_id integer, payload jsonb, 55 | ts timestamptz not null default current_timestamp 56 | ); 57 | 58 | 59 | alter table sm_log set schema sm; 60 | 61 | -- Something critically important is missing, right? -------------------------------------------------------------------------------- /On-the-board/state-machine/State machine II.sql: -------------------------------------------------------------------------------- 1 | -- drop table if exists state; 2 | create table state ( 3 | id serial primary key, 4 | state_name text not null, 5 | details jsonb not null default '{}' 6 | ); 7 | 8 | 9 | -- drop table if exists signal; 10 | create table signal ( 11 | id serial primary key, 12 | signal_name text not null, 13 | details jsonb not null default '{}' 14 | ); 15 | 16 | 17 | -- drop table if exists transition; 18 | create table transition ( 19 | signal_id integer not null references signal(id), 20 | in_state_id integer not null references state(id), 21 | out_state_id integer not null references state(id), 22 | transition_handler text not null default '', 23 | details jsonb not null default '{}' 24 | ); 25 | 26 | 27 | -- drop table if exists sm_unit; 28 | create table sm_unit ( 29 | id serial primary key, 30 | unit_name text not null, 31 | unit_details jsonb not null default '{}' 32 | ); 33 | 34 | insert into state (state_name) values ('registered'),('assigned'),('dispatched'), 35 | ('start of service'),('end of service'),('reported'); 36 | 37 | insert into signal(signal_name) values ('customer call'),('assign'),('dispatch'), 38 | ('arrive'),('parts missing'),('parts picked ok'),('parts picked failed'), 39 | ('finished work ok'),('finished work failed'),('customer notification'); 40 | 41 | insert into state (state_name) values ('neutral'); 42 | insert into state (state_name) values ('parts missing'); 43 | insert into signal (signal_name) values ('time interval'); 44 | 45 | select * from state; 46 | 47 | insert into transition (signal_id,in_state_id,out_state_id) values 48 | (1,7,1),--customer call, neutral->registered 49 | (2,1,2),--assign, registered->assign 50 | (3,2,3),--dispatched, assign->dispatched 51 | (4,3,4),--arrive, dispatched->start of service 52 | (5,4,8),--parts missing, start of service->parts missing 53 | (6,8,4),--parts picked ok, parts missing->start of service 54 | (7,8,2) --parts picked failed, parts missing->assign 55 | 56 | select s.signal_name,s2.state_name as in_state,s3.state_name as out_state 57 | from transition t join signal s on s.id = signal_id 58 | join state s2 on s2.id = in_state_id 59 | join state s3 on s3.id=out_state_id 60 | -------------------------------------------------------------------------------- /PostgreSQL Python.md: -------------------------------------------------------------------------------- 1 | # PostgreSQL [psycopg](https://www.psycopg.org/psycopg3/docs/basic/index.html) and Python [DB-API 2.0](https://peps.python.org/pep-0249/) 2 | > [!TIP] 3 | > If not already there: 4 | > 5 | > [Download](https://www.python.org/downloads/) and run **Python 3** installer 6 | > Install **psycopg**. Run `path-to\pip install psycopg` 7 | > 8 | > (usually `C:\Users\\AppData\Local\Programs\Python\Python313\Scripts\pip`) 9 | ## I. Connection 10 | ### psycopg connection using a connection string 11 | 12 | ```Python 13 | import psycopg as pg 14 | 15 | # Literal connection string 16 | connectionstring = "host='localhost' dbname='my_database' user='postgres' password='secret'" 17 | 18 | # Interpolated connection string 19 | conn_paramaters = ('the_database', 'the_user', 'secret', 'the_host', 5432) # these may come from somewhere else 20 | connectionstring = "dbname='%s' user='%s' password='%s' host='%s' port=%s" % conn_paramaters 21 | 22 | conn = pg.connect(connectionstring) 23 | ``` 24 | ### psycopg connection using separate arguments 25 | 26 | ```Python 27 | conn = pg.connect(dbname='the_database', user='the_user', password='secret', host='the_host', port=5432) 28 | ``` 29 | 30 | ### psycopg connection using environment variables 31 | ```Python 32 | conn = pg.connect('') 33 | ``` 34 | **Variables:** 35 | - PGHOST 36 | - PGPORT 37 | - PGHOSTADDR 38 | - PGDATABASE 39 | - PGUSER 40 | - PGPASSWORD 41 | 42 | More in the [documentation](https://www.postgresql.org/docs/current/libpq-envars.html) 43 | 44 | ## II. Statement, weirdly called [cursor](https://www.psycopg.org/psycopg3/docs/api/cursors.html#the-cursor-class) in Python 45 | 46 | ```python 47 | stmt = conn.cursor() 48 | ``` 49 | #### a good structure example 50 | ```Python 51 | with pg.connect(connectionstring) as conn: 52 | with conn.cursor() as stmt: 53 | # stmt.execute and stmt.fetch* statements 54 | conn.commit() 55 | ``` 56 | #### step by step 57 | ```Python 58 | import psycopg as pg 59 | 60 | # these shall come from a safe place 61 | conn_paramaters = ('practice', 'postgres', 'TheLongPassword', 'localhost', 5432) 62 | 63 | connectionstring = "dbname='%s' user='%s' password='%s' host='%s' port=%s" % conn_paramaters 64 | 65 | # this may come from a SQL module 66 | sql = 'select * from class_a.unit' 67 | 68 | conn = pg.connect(connectionstring) 69 | stmt = conn.cursor() 70 | stmt.execute(sql) 71 | 72 | res = stmt.fetchall() 73 | print (res) 74 | 75 | conn.commit() 76 | stmt.close() 77 | conn.close() 78 | ``` 79 | > [!NOTE] 80 | > You may have a look at [this](https://github.com/stefanov-sm/sql-methods-in-python) example 81 | > and the highly efficient PostgreSQL specific [copy](https://www.psycopg.org/psycopg3/docs/basic/copy.html) 82 | 83 | ## III. _Must_ read 84 | 85 | > [!IMPORTANT] 86 | > [Passing parameters](https://www.psycopg.org/psycopg3/docs/basic/params.html) to SQL queries 87 | > Statement result format by [Row factories](https://www.psycopg.org/psycopg3/docs/advanced/rows.html) 88 | > [Transaction management](https://www.psycopg.org/psycopg3/docs/basic/transactions.html) 89 | -------------------------------------------------------------------------------- /README.md: -------------------------------------------------------------------------------- 1 | # Database XI 2 | 3 | > [!NOTE] 4 | > Dear young colleagues, 5 | > I will be placing course-related materials in this repository. 6 | > S. Stefanov 7 | 8 | #### Foreign data. [Postgres OnLine Journal](https://www.postgresonline.com/) Windows binaries of [FDW](https://www.postgresql.org/docs/current/ddl-foreign-data.html) & extensions [here](https://www.postgresonline.com/winextensions.php) and [here](https://www.postgresonline.com/journal/index.php?/categories/47-postgresql-versions) 9 | #### Sample data 10 | ECB Foreign Exchange Rates [history](https://www.ecb.europa.eu/stats/eurofxref/eurofxref-hist.zip) 11 | 12 | #### My [State machines' farm implementation](https://github.com/stefanov-sm/state-machine-farm) 13 | -------------------------------------------------------------------------------- /Regular expressions/RegExp Cheat Sheet.pdf: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/stefanov-sm/Database-XI/3d4c68199bb9cf0bee3567f51180b3834996a164/Regular expressions/RegExp Cheat Sheet.pdf -------------------------------------------------------------------------------- /Regular expressions/regex.sql: -------------------------------------------------------------------------------- 1 | create temporary table a_table (id integer, address text); 2 | insert into a_table 3 | values 4 | (1, 'Студентски Комплекс, ул. „Росарио“ 1, 1756 София'), 5 | (2, 'кв. Дианабад.19 Г, 1172 София'), 6 | (3, '4000 Пловдив Център, ул. „Иван Вазов“ 59'), 7 | (4, 'ж.к. Лозенец, бул. „Джеймс Баучер“ 5, 1164 София'); 8 | 9 | select id, substring(address from '\y(\d{4})\y') as zipcode 10 | from a_table; 11 | 12 | select * from a_table 13 | where address ~ 'ул\.'; 14 | 15 | select * from a_table 16 | where address ~ '\yул\.' -- note Y vs. У 17 | or address ~* '^КВ\..*ОФИЯ$'; 18 | 19 | select * 20 | from regexp_split_to_table('Hello regexp. power - at my fingertips!', '[, \.!+-]+') as rs; 21 | 22 | discard all; -- this would drop temporary objects 23 | -------------------------------------------------------------------------------- /Resources.pdf: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/stefanov-sm/Database-XI/3d4c68199bb9cf0bee3567f51180b3834996a164/Resources.pdf -------------------------------------------------------------------------------- /W3Schools demo DB DDL/Northwind.png: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/stefanov-sm/Database-XI/3d4c68199bb9cf0bee3567f51180b3834996a164/W3Schools demo DB DDL/Northwind.png -------------------------------------------------------------------------------- /W3Schools demo DB DDL/README.md: -------------------------------------------------------------------------------- 1 | ## W3Schools [PostgreSQL tutorial](https://www.w3schools.com/postgresql/index.php) demo database DDL 2 | ## Populat Northwind demo database dump and ERD 3 | -------------------------------------------------------------------------------- /W3Schools demo DB DDL/W3S-Postgres-dd.sql: -------------------------------------------------------------------------------- 1 | CREATE TABLE categories 2 | ( 3 | category_id SERIAL NOT NULL PRIMARY KEY, 4 | category_name text, 5 | description text 6 | ); 7 | 8 | INSERT INTO categories (category_name, description) 9 | VALUES 10 | ('Beverages', 'Soft drinks, coffees, teas, beers, and ales'), 11 | ('Condiments', 'Sweet and savory sauces, relishes, spreads, and seasonings'), 12 | ('Confections', 'Desserts, candies, and sweet breads'), 13 | ('Dairy Products', 'Cheeses'), 14 | ('Grains/Cereals', 'Breads, crackers, pasta, and cereal'), 15 | ('Meat/Poultry', 'Prepared meats'), 16 | ('Produce', 'Dried fruit and bean curd'), 17 | ('Seafood', 'Seaweed and fish'); 18 | 19 | CREATE TABLE customers ( 20 | customer_id SERIAL NOT NULL PRIMARY KEY, 21 | customer_name text, 22 | contact_name text, 23 | address text, 24 | city text, 25 | postal_code text, 26 | country text 27 | ); 28 | 29 | INSERT INTO customers (customer_name, contact_name, address, city, postal_code, country) 30 | VALUES 31 | ('Alfreds Futterkiste', 'Maria Anders', 'Obere Str. 57', 'Berlin', '12209', 'Germany'), 32 | ('Ana Trujillo Emparedados y helados', 'Ana Trujillo', 'Avda. de la Constitucion 2222', 'Mexico D.F.', '05021', 'Mexico'), 33 | ('Antonio Moreno Taquera', 'Antonio Moreno', 'Mataderos 2312', 'Mexico D.F.', '05023', 'Mexico'), 34 | ('Around the Horn', 'Thomas Hardy', '120 Hanover Sq.', 'London', 'WA1 1DP', 'UK'), 35 | ('Berglunds snabbkoep', 'Christina Berglund', 'Berguvsvegen 8', 'Lulea', 'S-958 22', 'Sweden'), 36 | ('Blauer See Delikatessen', 'Hanna Moos', 'Forsterstr. 57', 'Mannheim', '68306', 'Germany'), 37 | ('Blondel pere et fils', 'Frederique Citeaux', '24, place Kleber', 'Strasbourg', '67000', 'France'), 38 | ('Bolido Comidas preparadas', 'Martin Sommer', 'C/ Araquil, 67', 'Madrid', '28023', 'Spain'), 39 | ('Bon app', 'Laurence Lebihans', '12, rue des Bouchers', 'Marseille', '13008', 'France'), 40 | ('Bottom-Dollar Marketse', 'Elizabeth Lincoln', '23 Tsawassen Blvd.', 'Tsawassen', 'T2F 8M4', 'Canada'), 41 | ('Bs Beverages', 'Victoria Ashworth', 'Fauntleroy Circus', 'London', 'EC2 5NT', 'UK'), 42 | ('Cactus Comidas para llevar', 'Patricio Simpson', 'Cerrito 333', 'Buenos Aires', '1010', 'Argentina'), 43 | ('Centro comercial Moctezuma', 'Francisco Chang', 'Sierras de Granada 9993', 'Mexico D.F.', '05022', 'Mexico'), 44 | ('Chop-suey Chinese', 'Yang Wang', 'Hauptstr. 29', 'Bern', '3012', 'Switzerland'), 45 | ('Comercio Mineiro', 'Pedro Afonso', 'Av. dos Lusiadas, 23', 'Sao Paulo', '05432-043', 'Brazil'), 46 | ('Consolidated Holdings', 'Elizabeth Brown', 'Berkeley Gardens 12 Brewery ', 'London', 'WX1 6LT', 'UK'), 47 | ('Drachenblut Delikatessend', 'Sven Ottlieb', 'Walserweg 21', 'Aachen', '52066', 'Germany'), 48 | ('Du monde entier', 'Janine Labrune', '67, rue des Cinquante Otages', 'Nantes', '44000', 'France'), 49 | ('Eastern Connection', 'Ann Devon', '35 King George', 'London', 'WX3 6FW', 'UK'), 50 | ('Ernst Handel', 'Roland Mendel', 'Kirchgasse 6', 'Graz', '8010', 'Austria'), 51 | ('Familia Arquibaldo', 'Aria Cruz', 'Rua Oros, 92', 'Sao Paulo', '05442-030', 'Brazil'), 52 | ('FISSA Fabrica Inter. Salchichas S.A.', 'Diego Roel', 'C/ Moralzarzal, 86', 'Madrid', '28034', 'Spain'), 53 | ('Folies gourmandes', 'Martine Rance', '184, chaussee de Tournai', 'Lille', '59000', 'France'), 54 | ('Folk och fe HB', 'Maria Larsson', 'Akergatan 24', 'Brecke', 'S-844 67', 'Sweden'), 55 | ('Frankenversand', 'Peter Franken', 'Berliner Platz 43', 'Munchen', '80805', 'Germany'), 56 | ('France restauration', 'Carine Schmitt', '54, rue Royale', 'Nantes', '44000', 'France'), 57 | ('Franchi S.p.A.', 'Paolo Accorti', 'Via Monte Bianco 34', 'Torino', '10100', 'Italy'), 58 | ('Furia Bacalhau e Frutos do Mar', 'Lino Rodriguez ', 'Jardim das rosas n. 32', 'Lisboa', '1675', 'Portugal'), 59 | ('Galeria del gastronomo', 'Eduardo Saavedra', 'Rambla de Cataluna, 23', 'Barcelona', '08022', 'Spain'), 60 | ('Godos Cocina Tipica', 'Jose Pedro Freyre', 'C/ Romero, 33', 'Sevilla', '41101', 'Spain'), 61 | ('Gourmet Lanchonetes', 'Andre Fonseca', 'Av. Brasil, 442', 'Campinas', '04876-786', 'Brazil'), 62 | ('Great Lakes Food Market', 'Howard Snyder', '2732 Baker Blvd.', 'Eugene', '97403', 'USA'), 63 | ('GROSELLA-Restaurante', 'Manuel Pereira', '5th Ave. Los Palos Grandes', 'Caracas', '1081', 'Venezuela'), 64 | ('Hanari Carnes', 'Mario Pontes', 'Rua do Paco, 67', 'Rio de Janeiro', '05454-876', 'Brazil'), 65 | ('HILARION-Abastos', 'Carlos Hernandez', 'Carrera 22 con Ave. Carlos Soublette #8-35', 'San Cristobal', '5022', 'Venezuela'), 66 | ('Hungry Coyote Import Store', 'Yoshi Latimer', 'City Center Plaza 516 Main St.', 'Elgin', '97827', 'USA'), 67 | ('Hungry Owl All-Night Grocers', 'Patricia McKenna', '8 Johnstown Road', 'Cork', '', 'Ireland'), 68 | ('Island Trading', 'Helen Bennett', 'Garden House Crowther Way', 'Cowes', 'PO31 7PJ', 'UK'), 69 | ('Koniglich Essen', 'Philip Cramer', 'Maubelstr. 90', 'Brandenburg', '14776', 'Germany'), 70 | ('La corne d abondance', 'Daniel Tonini', '67, avenue de l Europe', 'Versailles', '78000', 'France'), 71 | ('La maison d Asie', 'Annette Roulet', '1 rue Alsace-Lorraine', 'Toulouse', '31000', 'France'), 72 | ('Laughing Bacchus Wine Cellars', 'Yoshi Tannamuri', '1900 Oak St.', 'Vancouver', 'V3F 2K1', 'Canada'), 73 | ('Lazy K Kountry Store', 'John Steel', '12 Orchestra Terrace', 'Walla Walla', '99362', 'USA'), 74 | ('Lehmanns Marktstand', 'Renate Messner', 'Magazinweg 7', 'Frankfurt a.M. ', '60528', 'Germany'), 75 | ('Lets Stop N Shop', 'Jaime Yorres', '87 Polk St. Suite 5', 'San Francisco', '94117', 'USA'), 76 | ('LILA-Supermercado', 'Carlos Gonzalez', 'Carrera 52 con Ave. Bolivar #65-98 Llano Largo', 'Barquisimeto', '3508', 'Venezuela'), 77 | ('LINO-Delicateses', 'Felipe Izquierdo', 'Ave. 5 de Mayo Porlamar', 'I. de Margarita', '4980', 'Venezuela'), 78 | ('Lonesome Pine Restaurant', 'Fran Wilson', '89 Chiaroscuro Rd.', 'Portland', '97219', 'USA'), 79 | ('Magazzini Alimentari Riuniti', 'Giovanni Rovelli', 'Via Ludovico il Moro 22', 'Bergamo', '24100', 'Italy'), 80 | ('Maison Dewey', 'Catherine Dewey', 'Rue Joseph-Bens 532', 'Bruxelles', 'B-1180', 'Belgium'), 81 | ('Mere Paillarde', 'Jean Fresniere', '43 rue St. Laurent', 'Montreal', 'H1J 1C3', 'Canada'), 82 | ('Morgenstern Gesundkost', 'Alexander Feuer', 'Heerstr. 22', 'Leipzig', '04179', 'Germany'), 83 | ('North/South', 'Simon Crowther', 'South House 300 Queensbridge', 'London', 'SW7 1RZ', 'UK'), 84 | ('Oceano Atlantico Ltda.', 'Yvonne Moncada', 'Ing. Gustavo Moncada 8585 Piso 20-A', 'Buenos Aires', '1010', 'Argentina'), 85 | ('Old World Delicatessen', 'Rene Phillips', '2743 Bering St.', 'Anchorage', '99508', 'USA'), 86 | ('Ottilies Keseladen', 'Henriette Pfalzheim', 'Mehrheimerstr. 369', 'Koln', '50739', 'Germany'), 87 | ('Paris specialites', 'Marie Bertrand', '265, boulevard Charonne', 'Paris', '75012', 'France'), 88 | ('Pericles Comidas clasicas', 'Guillermo Fernandez', 'Calle Dr. Jorge Cash 321', 'Mexico D.F.', '05033', 'Mexico'), 89 | ('Piccolo und mehr', 'Georg Pipps', 'Geislweg 14', 'Salzburg', '5020', 'Austria'), 90 | ('Princesa Isabel Vinhoss', 'Isabel de Castro', 'Estrada da saude n. 58', 'Lisboa', '1756', 'Portugal'), 91 | ('Que Delicia', 'Bernardo Batista', 'Rua da Panificadora, 12', 'Rio de Janeiro', '02389-673', 'Brazil'), 92 | ('Queen Cozinha', 'Lucia Carvalho', 'Alameda dos Canarios, 891', 'Sao Paulo', '05487-020', 'Brazil'), 93 | ('QUICK-Stop', 'Horst Kloss', 'Taucherstrasse 10', 'Cunewalde', '01307', 'Germany'), 94 | ('Rancho grande', 'Sergio Gutiarrez', 'Av. del Libertador 900', 'Buenos Aires', '1010', 'Argentina'), 95 | ('Rattlesnake Canyon Grocery', 'Paula Wilson', '2817 Milton Dr.', 'Albuquerque', '87110', 'USA'), 96 | ('Reggiani Caseifici', 'Maurizio Moroni', 'Strada Provinciale 124', 'Reggio Emilia', '42100', 'Italy'), 97 | ('Ricardo Adocicados', 'Janete Limeira', 'Av. Copacabana, 267', 'Rio de Janeiro', '02389-890', 'Brazil'), 98 | ('Richter Supermarkt', 'Michael Holz', 'Grenzacherweg 237', 'Geneve', '1203', 'Switzerland'), 99 | ('Romero y tomillo', 'Alejandra Camino', 'Gran Via, 1', 'Madrid', '28001', 'Spain'), 100 | ('Santa Gourmet', 'Jonas Bergulfsen', 'Erling Skakkes gate 78', 'Stavern', '4110', 'Norway'), 101 | ('Save-a-lot Markets', 'Jose Pavarotti', '187 Suffolk Ln.', 'Boise', '83720', 'USA'), 102 | ('Seven Seas Imports', 'Hari Kumar', '90 Wadhurst Rd.', 'London', 'OX15 4NB', 'UK'), 103 | ('Simons bistro', 'Jytte Petersen', 'Vinbeltet 34', 'Kobenhavn', '1734', 'Denmark'), 104 | ('Specialites du monde', 'Dominique Perrier', '25, rue Lauriston', 'Paris', '75016', 'France'), 105 | ('Split Rail Beer & Ale', 'Art Braunschweiger', 'P.O. Box 555', 'Lander', '82520', 'USA'), 106 | ('Supremes delices', 'Pascale Cartrain', 'Boulevard Tirou, 255', 'Charleroi', 'B-6000', 'Belgium'), 107 | ('The Big Cheese', 'Liz Nixon', '89 Jefferson Way Suite 2', 'Portland', '97201', 'USA'), 108 | ('The Cracker Box', 'Liu Wong', '55 Grizzly Peak Rd.', 'Butte', '59801', 'USA'), 109 | ('Toms Spezialiteten', 'Karin Josephs', 'Luisenstr. 48', 'Manster', '44087', 'Germany'), 110 | ('Tortuga Restaurante', 'Miguel Angel Paolino', 'Avda. Azteca 123', 'Mexico D.F.', '05033', 'Mexico'), 111 | ('Tradicao Hipermercados', 'Anabela Domingues', 'Av. Ines de Castro, 414', 'Sao Paulo', '05634-030', 'Brazil'), 112 | ('Trails Head Gourmet Provisioners', 'Helvetius Nagy', '722 DaVinci Blvd.', 'Kirkland', '98034', 'USA'), 113 | ('Vaffeljernet', 'Palle Ibsen', 'Smagsloget 45', 'Arhus', '8200', 'Denmark'), 114 | ('Victuailles en stock', 'Mary Saveley', '2, rue du Commerce', 'Lyon', '69004', 'France'), 115 | ('Vins et alcools Chevalier', 'Paul Henriot', '59 rue de l Abbaye', 'Reims', '51100', 'France'), 116 | ('Die Wandernde Kuh', 'Rita Moller', 'Adenauerallee 900', 'Stuttgart', '70563', 'Germany'), 117 | ('Wartian Herkku', 'Pirkko Koskitalo', 'Torikatu 38', 'Oulu', '90110', 'Finland'), 118 | ('Wellington Importadora', 'Paula Parente', 'Rua do Mercado, 12', 'Resende', '08737-363', 'Brazil'), 119 | ('White Clover Markets', 'Karl Jablonski', '305 - 14th Ave. S. Suite 3B', 'Seattle', '98128', 'USA'), 120 | ('Wilman Kala', 'Matti Karttunen', 'Keskuskatu 45', 'Helsinki', '21240', 'Finland'), 121 | ('Wolski', 'Zbyszek', 'ul. Filtrowa 68', 'Walla', '01-012', 'Poland'); 122 | 123 | CREATE TABLE products ( 124 | product_id SERIAL NOT NULL PRIMARY KEY, 125 | product_name text, 126 | category_id INT, 127 | unit text, 128 | price DECIMAL(10, 2) 129 | ); 130 | 131 | INSERT INTO products (product_id, product_name, category_id, unit, price) 132 | VALUES 133 | (1, 'Chais', 1, '10 boxes x 20 bags', 18), 134 | (2, 'Chang', 1, '24 - 12 oz bottles', 19), 135 | (3, 'Aniseed Syrup', 2, '12 - 550 ml bottles', 10), 136 | (4, 'Chef Antons Cajun Seasoning', 2, '48 - 6 oz jars', 22), 137 | (5, 'Chef Antons Gumbo Mix', 2, '36 boxes', 21.35), 138 | (6, 'Grandmas Boysenberry Spread', 2, '12 - 8 oz jars', 25), 139 | (7, 'Uncle Bobs Organic Dried Pears', 7, '12 - 1 lb pkgs.', 30), 140 | (8, 'Northwoods Cranberry Sauce', 2, '12 - 12 oz jars', 40), 141 | (9, 'Mishi Kobe Niku', 6, '18 - 500 g pkgs.', 97), 142 | (10, 'Ikura', 8, '12 - 200 ml jars', 31), 143 | (11, 'Queso Cabrales', 4, '1 kg pkg.', 21), 144 | (12, 'Queso Manchego La Pastora', 4, '10 - 500 g pkgs.', 38), 145 | (13, 'Konbu', 8, '2 kg box', 6), 146 | (14, 'Tofu', 7, '40 - 100 g pkgs.', 23.25), 147 | (15, 'Genen Shouyu', 2, '24 - 250 ml bottles', 15.5), 148 | (16, 'Pavlova', 3, '32 - 500 g boxes', 17.45), 149 | (17, 'Alice Mutton', 6, '20 - 1 kg tins', 39), 150 | (18, 'Carnarvon Tigers', 8, '16 kg pkg.', 62.5), 151 | (19, 'Teatime Chocolate Biscuits', 3, '10 boxes x 12 pieces', 9.2), 152 | (20, 'Sir Rodneys Marmalade', 3, '30 gift boxes', 81), 153 | (21, 'Sir Rodneys Scones', 3, '24 pkgs. x 4 pieces', 10), 154 | (22, 'Gustafs Kneckebrod', 5, '24 - 500 g pkgs.', 21), 155 | (23, 'Tunnbrod', 5, '12 - 250 g pkgs.', 9), 156 | (24, 'Guarani Fantastica', 1, '12 - 355 ml cans', 4.5), 157 | (25, 'NuNuCa Nui-Nougat-Creme', 3, '20 - 450 g glasses', 14), 158 | (26, 'Gumber Gummiberchen', 3, '100 - 250 g bags', 31.23), 159 | (27, 'Schoggi Schokolade', 3, '100 - 100 g pieces', 43.9), 160 | (28, 'Rassle Sauerkraut', 7, '25 - 825 g cans', 45.6), 161 | (29, 'Thoringer Rostbratwurst', 6, '50 bags x 30 sausgs.', 123.79), 162 | (30, 'Nord-Ost Matjeshering', 8, '10 - 200 g glasses', 25.89), 163 | (31, 'Gorgonzola Telino', 4, '12 - 100 g pkgs', 12.5), 164 | (32, 'Mascarpone Fabioli', 4, '24 - 200 g pkgs.', 32), 165 | (33, 'Geitost', 4, '500 g', 2.5), 166 | (34, 'Sasquatch Ale', 1, '24 - 12 oz bottles', 14), 167 | (35, 'Steeleye Stout', 1, '24 - 12 oz bottles', 18), 168 | (36, 'Inlagd Sill', 8, '24 - 250 g jars', 19), 169 | (37, 'Gravad lax', 8, '12 - 500 g pkgs.', 26), 170 | (38, 'Cote de Blaye', 1, '12 - 75 cl bottles', 263.5), 171 | (39, 'Chartreuse verte', 1, '750 cc per bottle', 18), 172 | (40, 'Boston Crab Meat', 8, '24 - 4 oz tins', 18.4), 173 | (41, 'Jacks New England Clam Chowder', 8, '12 - 12 oz cans', 9.65), 174 | (42, 'Singaporean Hokkien Fried Mee', 5, '32 - 1 kg pkgs.', 14), 175 | (43, 'Ipoh Coffee', 1, '16 - 500 g tins', 46), 176 | (44, 'Gula Malacca', 2, '20 - 2 kg bags', 19.45), 177 | (45, 'Rogede sild', 8, '1k pkg.', 9.5), 178 | (46, 'Spegesild', 8, '4 - 450 g glasses', 12), 179 | (47, 'Zaanse koeken', 3, '10 - 4 oz boxes', 9.5), 180 | (48, 'Chocolade', 3, '10 pkgs.', 12.75), 181 | (49, 'Maxilaku', 3, '24 - 50 g pkgs.', 20), 182 | (50, 'Valkoinen suklaa', 3, '12 - 100 g bars', 16.25), 183 | (51, 'Manjimup Dried Apples', 7, '50 - 300 g pkgs.', 53), 184 | (52, 'Filo Mix', 5, '16 - 2 kg boxes', 7), 185 | (53, 'Perth Pasties', 6, '48 pieces', 32.8), 186 | (54, 'Tourtiare', 6, '16 pies', 7.45), 187 | (55, 'Pate chinois', 6, '24 boxes x 2 pies', 24), 188 | (56, 'Gnocchi di nonna Alice', 5, '24 - 250 g pkgs.', 38), 189 | (57, 'Ravioli Angelo', 5, '24 - 250 g pkgs.', 19.5), 190 | (58, 'Escargots de Bourgogne', 8, '24 pieces', 13.25), 191 | (59, 'Raclette Courdavault', 4, '5 kg pkg.', 55), 192 | (60, 'Camembert Pierrot', 4, '15 - 300 g rounds', 34), 193 | (61, 'Sirop d arable', 2, '24 - 500 ml bottles', 28.5), 194 | (62, 'Tarte au sucre', 3, '48 pies', 49.3), 195 | (63, 'Vegie-spread', 2, '15 - 625 g jars', 43.9), 196 | (64, 'Wimmers gute Semmelknadel', 5, '20 bags x 4 pieces', 33.25), 197 | (65, 'Louisiana Fiery Hot Pepper Sauce', 2, '32 - 8 oz bottles', 21.05), 198 | (66, 'Louisiana Hot Spiced Okra', 2, '24 - 8 oz jars', 17), 199 | (67, 'Laughing Lumberjack Lager', 1, '24 - 12 oz bottles', 14), 200 | (68, 'Scottish Longbreads', 3, '10 boxes x 8 pieces', 12.5), 201 | (69, 'Gudbrandsdalsost', 4, '10 kg pkg.', 36), 202 | (70, 'Outback Lager', 1, '24 - 355 ml bottles', 15), 203 | (71, 'Flotemysost', 4, '10 - 500 g pkgs.', 21.5), 204 | (72, 'Mozzarella di Giovanni', 4, '24 - 200 g pkgs.', 34.8), 205 | (73, 'Red Kaviar', 8, '24 - 150 g jars', 15), 206 | (74, 'Longlife Tofu', 7, '5 kg pkg.', 10), 207 | (75, 'Rhenbreu Klosterbier', 1, '24 - 0.5 l bottles', 7.75), 208 | (76, 'Lakkalikeeri', 1, '500 ml ', 18), 209 | (77, 'Original Frankfurter grone Soae', 2, '12 boxes', 13); 210 | 211 | CREATE TABLE orders ( 212 | order_id SERIAL NOT NULL PRIMARY KEY, 213 | customer_id INT, 214 | order_date DATE 215 | ); 216 | 217 | INSERT INTO orders (order_id, customer_id, order_date) 218 | VALUES 219 | (10248, 90, '2021-07-04'), 220 | (10249, 81, '2021-07-05'), 221 | (10250, 34, '2021-07-08'), 222 | (10251, 84, '2021-07-08'), 223 | (10252, 76, '2021-07-09'), 224 | (10253, 34, '2021-07-10'), 225 | (10254, 14, '2021-07-11'), 226 | (10255, 68, '2021-07-12'), 227 | (10256, 88, '2021-07-15'), 228 | (10257, 35, '2021-07-16'), 229 | (10258, 20, '2021-07-17'), 230 | (10259, 13, '2021-07-18'), 231 | (10260, 55, '2021-07-19'), 232 | (10261, 61, '2021-07-19'), 233 | (10262, 65, '2021-07-22'), 234 | (10263, 20, '2021-07-23'), 235 | (10264, 24, '2021-07-24'), 236 | (10265, 7, '2021-07-25'), 237 | (10266, 87, '2021-07-26'), 238 | (10267, 25, '2021-07-29'), 239 | (10268, 33, '2021-07-30'), 240 | (10269, 89, '2021-07-31'), 241 | (10270, 87, '2021-08-01'), 242 | (10271, 75, '2021-08-01'), 243 | (10272, 65, '2021-08-02'), 244 | (10273, 63, '2021-08-05'), 245 | (10274, 85, '2021-08-06'), 246 | (10275, 49, '2021-08-07'), 247 | (10276, 80, '2021-08-08'), 248 | (10277, 52, '2021-08-09'), 249 | (10278, 5, '2021-08-12'), 250 | (10279, 44, '2021-08-13'), 251 | (10280, 5, '2021-08-14'), 252 | (10281, 69, '2021-08-14'), 253 | (10282, 69, '2021-08-15'), 254 | (10283, 46, '2021-08-16'), 255 | (10284, 44, '2021-08-19'), 256 | (10285, 63, '2021-08-20'), 257 | (10286, 63, '2021-08-21'), 258 | (10287, 67, '2021-08-22'), 259 | (10288, 66, '2021-08-23'), 260 | (10289, 11, '2021-08-26'), 261 | (10290, 15, '2021-08-27'), 262 | (10291, 61, '2021-08-27'), 263 | (10292, 81, '2021-08-28'), 264 | (10293, 80, '2021-08-29'), 265 | (10294, 65, '2021-08-30'), 266 | (10295, 85, '2021-09-02'), 267 | (10296, 46, '2021-09-03'), 268 | (10297, 7, '2021-09-04'), 269 | (10298, 37, '2021-09-05'), 270 | (10299, 67, '2021-09-06'), 271 | (10300, 49, '2021-09-09'), 272 | (10301, 86, '2021-09-09'), 273 | (10302, 76, '2021-09-10'), 274 | (10303, 30, '2021-09-11'), 275 | (10304, 80, '2021-09-12'), 276 | (10305, 55, '2021-09-13'), 277 | (10306, 69, '2021-09-16'), 278 | (10307, 48, '2021-09-17'), 279 | (10308, 2, '2021-09-18'), 280 | (10309, 37, '2021-09-19'), 281 | (10310, 77, '2021-09-20'), 282 | (10311, 18, '2021-09-20'), 283 | (10312, 86, '2021-09-23'), 284 | (10313, 63, '2021-09-24'), 285 | (10314, 65, '2021-09-25'), 286 | (10315, 38, '2021-09-26'), 287 | (10316, 65, '2021-09-27'), 288 | (10317, 48, '2021-09-30'), 289 | (10318, 38, '2021-10-01'), 290 | (10319, 80, '2021-10-02'), 291 | (10320, 87, '2021-10-03'), 292 | (10321, 38, '2021-10-03'), 293 | (10322, 58, '2021-10-04'), 294 | (10323, 39, '2021-10-07'), 295 | (10324, 71, '2021-10-08'), 296 | (10325, 39, '2021-10-09'), 297 | (10326, 8, '2021-10-10'), 298 | (10327, 24, '2021-10-11'), 299 | (10328, 28, '2021-10-14'), 300 | (10329, 75, '2021-10-15'), 301 | (10330, 46, '2021-10-16'), 302 | (10331, 9, '2021-10-16'), 303 | (10332, 51, '2021-10-17'), 304 | (10333, 87, '2021-10-18'), 305 | (10334, 84, '2021-10-21'), 306 | (10335, 37, '2021-10-22'), 307 | (10336, 60, '2021-10-23'), 308 | (10337, 25, '2021-10-24'), 309 | (10338, 55, '2021-10-25'), 310 | (10339, 51, '2021-10-28'), 311 | (10340, 9, '2021-10-29'), 312 | (10341, 73, '2021-10-29'), 313 | (10342, 25, '2021-10-30'), 314 | (10343, 44, '2021-10-31'), 315 | (10344, 89, '2021-11-01'), 316 | (10345, 63, '2021-11-04'), 317 | (10346, 65, '2021-11-05'), 318 | (10347, 21, '2021-11-06'), 319 | (10348, 86, '2021-11-07'), 320 | (10349, 75, '2021-11-08'), 321 | (10350, 41, '2021-11-11'), 322 | (10351, 20, '2021-11-11'), 323 | (10352, 28, '2021-11-12'), 324 | (10353, 59, '2021-11-13'), 325 | (10354, 58, '2021-11-14'), 326 | (10355, 4, '2021-11-15'), 327 | (10356, 86, '2021-11-18'), 328 | (10357, 46, '2021-11-19'), 329 | (10358, 41, '2021-11-20'), 330 | (10359, 72, '2021-11-21'), 331 | (10360, 7, '2021-11-22'), 332 | (10361, 63, '2021-11-22'), 333 | (10362, 9, '2021-11-25'), 334 | (10363, 17, '2021-11-26'), 335 | (10364, 19, '2021-11-26'), 336 | (10365, 3, '2021-11-27'), 337 | (10366, 29, '2021-11-28'), 338 | (10367, 83, '2021-11-28'), 339 | (10368, 20, '2021-11-29'), 340 | (10369, 75, '2021-12-02'), 341 | (10370, 14, '2021-12-03'), 342 | (10371, 41, '2021-12-03'), 343 | (10372, 62, '2021-12-04'), 344 | (10373, 37, '2021-12-05'), 345 | (10374, 91, '2021-12-05'), 346 | (10375, 36, '2021-12-06'), 347 | (10376, 51, '2021-12-09'), 348 | (10377, 72, '2021-12-09'), 349 | (10378, 24, '2021-12-10'), 350 | (10379, 61, '2021-12-11'), 351 | (10380, 37, '2021-12-12'), 352 | (10381, 46, '2021-12-12'), 353 | (10382, 20, '2021-12-13'), 354 | (10383, 4, '2021-12-16'), 355 | (10384, 5, '2021-12-16'), 356 | (10385, 75, '2021-12-17'), 357 | (10386, 21, '2021-12-18'), 358 | (10387, 70, '2021-12-18'), 359 | (10388, 72, '2021-12-19'), 360 | (10389, 10, '2021-12-20'), 361 | (10390, 20, '2021-12-23'), 362 | (10391, 17, '2021-12-23'), 363 | (10392, 59, '2021-12-24'), 364 | (10393, 71, '2021-12-25'), 365 | (10394, 36, '2021-12-25'), 366 | (10395, 35, '2021-12-26'), 367 | (10396, 25, '2021-12-27'), 368 | (10397, 60, '2021-12-27'), 369 | (10398, 71, '2021-12-30'), 370 | (10399, 83, '2021-12-31'), 371 | (10400, 19, '2022-01-01'), 372 | (10401, 65, '2022-01-01'), 373 | (10402, 20, '2022-01-02'), 374 | (10403, 20, '2022-01-03'), 375 | (10404, 49, '2022-01-03'), 376 | (10405, 47, '2022-01-06'), 377 | (10406, 62, '2022-01-07'), 378 | (10407, 56, '2022-01-07'), 379 | (10408, 23, '2022-01-08'), 380 | (10409, 54, '2022-01-09'), 381 | (10410, 10, '2022-01-10'), 382 | (10411, 10, '2022-01-10'), 383 | (10412, 87, '2022-01-13'), 384 | (10413, 41, '2022-01-14'), 385 | (10414, 21, '2022-01-14'), 386 | (10415, 36, '2022-01-15'), 387 | (10416, 87, '2022-01-16'), 388 | (10417, 73, '2022-01-16'), 389 | (10418, 63, '2022-01-17'), 390 | (10419, 68, '2022-01-20'), 391 | (10420, 88, '2022-01-21'), 392 | (10421, 61, '2022-01-21'), 393 | (10422, 27, '2022-01-22'), 394 | (10423, 31, '2022-01-23'), 395 | (10424, 51, '2022-01-23'), 396 | (10425, 41, '2022-01-24'), 397 | (10426, 29, '2022-01-27'), 398 | (10427, 59, '2022-01-27'), 399 | (10428, 66, '2022-01-28'), 400 | (10429, 37, '2022-01-29'), 401 | (10430, 20, '2022-01-30'), 402 | (10431, 10, '2022-01-30'), 403 | (10432, 75, '2022-01-31'), 404 | (10433, 60, '2022-02-03'), 405 | (10434, 24, '2022-02-03'), 406 | (10435, 16, '2022-02-04'), 407 | (10436, 7, '2022-02-05'), 408 | (10437, 87, '2022-02-05'), 409 | (10438, 79, '2022-02-06'), 410 | (10439, 51, '2022-02-07'), 411 | (10440, 71, '2022-02-10'), 412 | (10441, 55, '2022-02-10'), 413 | (10442, 20, '2022-02-11'), 414 | (10443, 66, '2022-02-12'), 415 | (10444, 5, '2022-02-12'), 416 | (10445, 5, '2022-02-13'), 417 | (10446, 79, '2022-02-14'), 418 | (10447, 67, '2022-02-14'), 419 | (10448, 64, '2022-02-17'), 420 | (10449, 7, '2022-02-18'), 421 | (10450, 84, '2022-02-19'), 422 | (10451, 63, '2022-02-19'), 423 | (10452, 71, '2022-02-20'), 424 | (10453, 4, '2022-02-21'), 425 | (10454, 41, '2022-02-21'), 426 | (10455, 87, '2022-02-24'), 427 | (10456, 39, '2022-02-25'), 428 | (10457, 39, '2022-02-25'), 429 | (10458, 76, '2022-02-26'), 430 | (10459, 84, '2022-02-27'), 431 | (10460, 24, '2022-02-28'), 432 | (10461, 46, '2022-02-28'), 433 | (10462, 16, '2022-03-03'), 434 | (10463, 76, '2022-03-04'), 435 | (10464, 28, '2022-03-04'), 436 | (10465, 83, '2022-03-05'), 437 | (10466, 15, '2022-03-06'), 438 | (10467, 49, '2022-03-06'), 439 | (10468, 39, '2022-03-07'), 440 | (10469, 89, '2022-03-10'), 441 | (10470, 9, '2022-03-11'), 442 | (10471, 11, '2022-03-11'), 443 | (10472, 72, '2022-03-12'), 444 | (10473, 38, '2022-03-13'), 445 | (10474, 58, '2022-03-13'), 446 | (10475, 76, '2022-03-14'), 447 | (10476, 35, '2022-03-17'), 448 | (10477, 60, '2022-03-17'), 449 | (10478, 84, '2022-03-18'), 450 | (10479, 65, '2022-03-19'), 451 | (10480, 23, '2022-03-20'), 452 | (10481, 67, '2022-03-20'), 453 | (10482, 43, '2022-03-21'), 454 | (10483, 89, '2022-03-24'), 455 | (10484, 11, '2022-03-24'), 456 | (10485, 47, '2022-03-25'), 457 | (10486, 35, '2022-03-26'), 458 | (10487, 62, '2022-03-26'), 459 | (10488, 25, '2022-03-27'), 460 | (10489, 59, '2022-03-28'), 461 | (10490, 35, '2022-03-31'), 462 | (10491, 28, '2022-03-31'), 463 | (10492, 10, '2022-04-01'), 464 | (10493, 41, '2022-04-02'), 465 | (10494, 15, '2022-04-02'), 466 | (10495, 42, '2022-04-03'), 467 | (10496, 81, '2022-04-04'), 468 | (10497, 44, '2022-04-04'), 469 | (10498, 35, '2022-04-07'), 470 | (10499, 46, '2022-04-08'), 471 | (10500, 41, '2022-04-09'), 472 | (10501, 6, '2022-04-09'), 473 | (10502, 58, '2022-04-10'), 474 | (10503, 37, '2022-04-11'), 475 | (10504, 89, '2022-04-11'), 476 | (10505, 51, '2022-04-14'), 477 | (10506, 39, '2022-04-15'), 478 | (10507, 3, '2022-04-15'), 479 | (10508, 56, '2022-04-16'), 480 | (10509, 6, '2022-04-17'), 481 | (10510, 71, '2022-04-18'), 482 | (10511, 9, '2022-04-18'), 483 | (10512, 21, '2022-04-21'), 484 | (10513, 86, '2022-04-22'), 485 | (10514, 20, '2022-04-22'), 486 | (10515, 63, '2022-04-23'), 487 | (10516, 37, '2022-04-24'), 488 | (10517, 53, '2022-04-24'), 489 | (10518, 80, '2022-04-25'), 490 | (10519, 14, '2022-04-28'), 491 | (10520, 70, '2022-04-29'), 492 | (10521, 12, '2022-04-29'), 493 | (10522, 44, '2022-04-30'), 494 | (10523, 72, '2022-05-01'), 495 | (10524, 5, '2022-05-01'), 496 | (10525, 9, '2022-05-02'), 497 | (10526, 87, '2022-05-05'), 498 | (10527, 63, '2022-05-05'), 499 | (10528, 32, '2022-05-06'), 500 | (10529, 50, '2022-05-07'), 501 | (10530, 59, '2022-05-08'), 502 | (10531, 54, '2022-05-08'), 503 | (10532, 19, '2022-05-09'), 504 | (10533, 24, '2022-05-12'), 505 | (10534, 44, '2022-05-12'), 506 | (10535, 3, '2022-05-13'), 507 | (10536, 44, '2022-05-14'), 508 | (10537, 68, '2022-05-14'), 509 | (10538, 11, '2022-05-15'), 510 | (10539, 11, '2022-05-16'), 511 | (10540, 63, '2022-05-19'), 512 | (10541, 34, '2022-05-19'), 513 | (10542, 39, '2022-05-20'), 514 | (10543, 46, '2022-05-21'), 515 | (10544, 48, '2022-05-21'), 516 | (10545, 43, '2022-05-22'), 517 | (10546, 84, '2022-05-23'), 518 | (10547, 72, '2022-05-23'), 519 | (10548, 79, '2022-05-26'), 520 | (10549, 63, '2022-05-27'), 521 | (10550, 30, '2022-05-28'), 522 | (10551, 28, '2022-05-28'), 523 | (10552, 35, '2022-05-29'), 524 | (10553, 87, '2022-05-30'), 525 | (10554, 56, '2022-05-30'), 526 | (10555, 71, '2022-06-02'), 527 | (10556, 73, '2022-06-03'), 528 | (10557, 44, '2022-06-03'), 529 | (10558, 4, '2022-06-04'), 530 | (10559, 7, '2022-06-05'), 531 | (10560, 25, '2022-06-06'), 532 | (10561, 24, '2022-06-06'), 533 | (10562, 66, '2022-06-09'), 534 | (10563, 67, '2022-06-10'), 535 | (10564, 65, '2022-06-10'), 536 | (10565, 51, '2022-06-11'), 537 | (10566, 7, '2022-06-12'), 538 | (10567, 37, '2022-06-12'), 539 | (10568, 29, '2022-06-13'), 540 | (10569, 65, '2022-06-16'), 541 | (10570, 51, '2022-06-17'), 542 | (10571, 20, '2022-06-17'), 543 | (10572, 5, '2022-06-18'), 544 | (10573, 3, '2022-06-19'), 545 | (10574, 82, '2022-06-19'), 546 | (10575, 52, '2022-06-20'), 547 | (10576, 80, '2022-06-23'), 548 | (10577, 82, '2022-06-23'), 549 | (10578, 11, '2022-06-24'), 550 | (10579, 45, '2022-06-25'), 551 | (10580, 56, '2022-06-26'), 552 | (10581, 21, '2022-06-26'), 553 | (10582, 6, '2022-06-27'), 554 | (10583, 87, '2022-06-30'), 555 | (10584, 7, '2022-06-30'), 556 | (10585, 88, '2022-07-01'), 557 | (10586, 66, '2022-07-02'), 558 | (10587, 61, '2022-07-02'), 559 | (10588, 63, '2022-07-03'), 560 | (10589, 32, '2022-07-04'), 561 | (10590, 51, '2022-07-07'), 562 | (10591, 83, '2022-07-07'), 563 | (10592, 44, '2022-07-08'), 564 | (10593, 44, '2022-07-09'), 565 | (10594, 55, '2022-07-09'), 566 | (10595, 20, '2022-07-10'), 567 | (10596, 89, '2022-07-11'), 568 | (10597, 59, '2022-07-11'), 569 | (10598, 65, '2022-07-14'), 570 | (10599, 11, '2022-07-15'), 571 | (10600, 36, '2022-07-16'), 572 | (10601, 35, '2022-07-16'), 573 | (10602, 83, '2022-07-17'), 574 | (10603, 71, '2022-07-18'), 575 | (10604, 28, '2022-07-18'), 576 | (10605, 51, '2022-07-21'), 577 | (10606, 81, '2022-07-22'), 578 | (10607, 71, '2022-07-22'), 579 | (10608, 79, '2022-07-23'), 580 | (10609, 18, '2022-07-24'), 581 | (10610, 41, '2022-07-25'), 582 | (10611, 91, '2022-07-25'), 583 | (10612, 71, '2022-07-28'), 584 | (10613, 35, '2022-07-29'), 585 | (10614, 6, '2022-07-29'), 586 | (10615, 90, '2022-07-30'), 587 | (10616, 32, '2022-07-31'), 588 | (10617, 32, '2022-07-31'), 589 | (10618, 51, '2022-08-01'), 590 | (10619, 51, '2022-08-04'), 591 | (10620, 42, '2022-08-05'), 592 | (10621, 38, '2022-08-05'), 593 | (10622, 67, '2022-08-06'), 594 | (10623, 25, '2022-08-07'), 595 | (10624, 78, '2022-08-07'), 596 | (10625, 2, '2022-08-08'), 597 | (10626, 5, '2022-08-11'), 598 | (10627, 71, '2022-08-11'), 599 | (10628, 7, '2022-08-12'), 600 | (10629, 30, '2022-08-12'), 601 | (10630, 39, '2022-08-13'), 602 | (10631, 41, '2022-08-14'), 603 | (10632, 86, '2022-08-14'), 604 | (10633, 20, '2022-08-15'), 605 | (10634, 23, '2022-08-15'), 606 | (10635, 49, '2022-08-18'), 607 | (10636, 87, '2022-08-19'), 608 | (10637, 62, '2022-08-19'), 609 | (10638, 47, '2022-08-20'), 610 | (10639, 70, '2022-08-20'), 611 | (10640, 86, '2022-08-21'), 612 | (10641, 35, '2022-08-22'), 613 | (10642, 73, '2022-08-22'), 614 | (10643, 1, '2022-08-25'), 615 | (10644, 88, '2022-08-25'), 616 | (10645, 34, '2022-08-26'), 617 | (10646, 37, '2022-08-27'), 618 | (10647, 61, '2022-08-27'), 619 | (10648, 67, '2022-08-28'), 620 | (10649, 50, '2022-08-28'), 621 | (10650, 21, '2022-08-29'), 622 | (10651, 86, '2022-09-01'), 623 | (10652, 31, '2022-09-01'), 624 | (10653, 25, '2022-09-02'), 625 | (10654, 5, '2022-09-02'), 626 | (10655, 66, '2022-09-03'), 627 | (10656, 32, '2022-09-04'), 628 | (10657, 71, '2022-09-04'), 629 | (10658, 63, '2022-09-05'), 630 | (10659, 62, '2022-09-05'), 631 | (10660, 36, '2022-09-08'), 632 | (10661, 37, '2022-09-09'), 633 | (10662, 48, '2022-09-09'), 634 | (10663, 9, '2022-09-10'), 635 | (10664, 28, '2022-09-10'), 636 | (10665, 48, '2022-09-11'), 637 | (10666, 68, '2022-09-12'), 638 | (10667, 20, '2022-09-12'), 639 | (10668, 86, '2022-09-15'), 640 | (10669, 73, '2022-09-15'), 641 | (10670, 25, '2022-09-16'), 642 | (10671, 26, '2022-09-17'), 643 | (10672, 5, '2022-09-17'), 644 | (10673, 90, '2022-09-18'), 645 | (10674, 38, '2022-09-18'), 646 | (10675, 25, '2022-09-19'), 647 | (10676, 80, '2022-09-22'), 648 | (10677, 3, '2022-09-22'), 649 | (10678, 71, '2022-09-23'), 650 | (10679, 7, '2022-09-23'), 651 | (10680, 55, '2022-09-24'), 652 | (10681, 32, '2022-09-25'), 653 | (10682, 3, '2022-09-25'), 654 | (10683, 18, '2022-09-26'), 655 | (10684, 56, '2022-09-26'), 656 | (10685, 31, '2022-09-29'), 657 | (10686, 59, '2022-09-30'), 658 | (10687, 37, '2022-09-30'), 659 | (10688, 83, '2022-10-01'), 660 | (10689, 5, '2022-10-01'), 661 | (10690, 34, '2022-10-02'), 662 | (10691, 63, '2022-10-03'), 663 | (10692, 1, '2022-10-03'), 664 | (10693, 89, '2022-10-06'), 665 | (10694, 63, '2022-10-06'), 666 | (10695, 90, '2022-10-07'), 667 | (10696, 89, '2022-10-08'), 668 | (10697, 47, '2022-10-08'), 669 | (10698, 20, '2022-10-09'), 670 | (10699, 52, '2022-10-09'), 671 | (10700, 71, '2022-10-10'), 672 | (10701, 37, '2022-10-13'), 673 | (10702, 1, '2022-10-13'), 674 | (10703, 24, '2022-10-14'), 675 | (10704, 62, '2022-10-14'), 676 | (10705, 35, '2022-10-15'), 677 | (10706, 55, '2022-10-16'), 678 | (10707, 4, '2022-10-16'), 679 | (10708, 77, '2022-10-17'), 680 | (10709, 31, '2022-10-17'), 681 | (10710, 27, '2022-10-20'), 682 | (10711, 71, '2022-10-21'), 683 | (10712, 37, '2022-10-21'), 684 | (10713, 71, '2022-10-22'), 685 | (10714, 71, '2022-10-22'), 686 | (10715, 9, '2022-10-23'), 687 | (10716, 64, '2022-10-24'), 688 | (10717, 25, '2022-10-24'), 689 | (10718, 39, '2022-10-27'), 690 | (10719, 45, '2022-10-27'), 691 | (10720, 61, '2022-10-28'), 692 | (10721, 63, '2022-10-29'), 693 | (10722, 71, '2022-10-29'), 694 | (10723, 89, '2022-10-30'), 695 | (10724, 51, '2022-10-30'), 696 | (10725, 21, '2022-10-31'), 697 | (10726, 19, '2022-11-03'), 698 | (10727, 66, '2022-11-03'), 699 | (10728, 62, '2022-11-04'), 700 | (10729, 47, '2022-11-04'), 701 | (10730, 9, '2022-11-05'), 702 | (10731, 14, '2022-11-06'), 703 | (10732, 9, '2022-11-06'), 704 | (10733, 5, '2022-11-07'), 705 | (10734, 31, '2022-11-07'), 706 | (10735, 45, '2022-11-10'), 707 | (10736, 37, '2022-11-11'), 708 | (10737, 85, '2022-11-11'), 709 | (10738, 74, '2022-11-12'), 710 | (10739, 85, '2022-11-12'), 711 | (10740, 89, '2022-11-13'), 712 | (10741, 4, '2022-11-14'), 713 | (10742, 10, '2022-11-14'), 714 | (10743, 4, '2022-11-17'), 715 | (10744, 83, '2022-11-17'), 716 | (10745, 63, '2022-11-18'), 717 | (10746, 14, '2022-11-19'), 718 | (10747, 59, '2022-11-19'), 719 | (10748, 71, '2022-11-20'), 720 | (10749, 38, '2022-11-20'), 721 | (10750, 87, '2022-11-21'), 722 | (10751, 68, '2022-11-24'), 723 | (10752, 53, '2022-11-24'), 724 | (10753, 27, '2022-11-25'), 725 | (10754, 49, '2022-11-25'), 726 | (10755, 9, '2022-11-26'), 727 | (10756, 75, '2022-11-27'), 728 | (10757, 71, '2022-11-27'), 729 | (10758, 68, '2022-11-28'), 730 | (10759, 2, '2022-11-28'), 731 | (10760, 50, '2022-12-01'), 732 | (10761, 65, '2022-12-02'), 733 | (10762, 24, '2022-12-02'), 734 | (10763, 23, '2022-12-03'), 735 | (10764, 20, '2022-12-03'), 736 | (10765, 63, '2022-12-04'), 737 | (10766, 56, '2022-12-05'), 738 | (10767, 76, '2022-12-05'), 739 | (10768, 4, '2022-12-08'), 740 | (10769, 83, '2022-12-08'), 741 | (10770, 34, '2022-12-09'), 742 | (10771, 20, '2022-12-10'), 743 | (10772, 44, '2022-12-10'), 744 | (10773, 20, '2022-12-11'), 745 | (10774, 24, '2022-12-11'), 746 | (10775, 78, '2022-12-12'), 747 | (10776, 20, '2022-12-15'), 748 | (10777, 31, '2022-12-15'), 749 | (10778, 5, '2022-12-16'), 750 | (10779, 52, '2022-12-16'), 751 | (10780, 46, '2022-12-16'), 752 | (10781, 87, '2022-12-17'), 753 | (10782, 12, '2022-12-17'), 754 | (10783, 34, '2022-12-18'), 755 | (10784, 49, '2022-12-18'), 756 | (10785, 33, '2022-12-18'), 757 | (10786, 62, '2022-12-19'), 758 | (10787, 41, '2022-12-19'), 759 | (10788, 63, '2022-12-22'), 760 | (10789, 23, '2022-12-22'), 761 | (10790, 31, '2022-12-22'), 762 | (10791, 25, '2022-12-23'), 763 | (10792, 91, '2022-12-23'), 764 | (10793, 4, '2022-12-24'), 765 | (10794, 61, '2022-12-24'), 766 | (10795, 20, '2022-12-24'), 767 | (10796, 35, '2022-12-25'), 768 | (10797, 17, '2022-12-25'), 769 | (10798, 38, '2022-12-26'), 770 | (10799, 39, '2022-12-26'), 771 | (10800, 72, '2022-12-26'), 772 | (10801, 8, '2022-12-29'), 773 | (10802, 73, '2022-12-29'), 774 | (10803, 88, '2022-12-30'), 775 | (10804, 72, '2022-12-30'), 776 | (10805, 77, '2022-12-30'), 777 | (10806, 84, '2022-12-31'), 778 | (10807, 27, '2022-12-31'), 779 | (10808, 60, '2023-01-01'), 780 | (10809, 88, '2023-01-01'), 781 | (10810, 42, '2023-01-01'), 782 | (10811, 47, '2023-01-02'), 783 | (10812, 66, '2023-01-02'), 784 | (10813, 67, '2023-01-05'), 785 | (10814, 84, '2023-01-05'), 786 | (10815, 71, '2023-01-05'), 787 | (10816, 32, '2023-01-06'), 788 | (10817, 39, '2023-01-06'), 789 | (10818, 49, '2023-01-07'), 790 | (10819, 12, '2023-01-07'), 791 | (10820, 65, '2023-01-07'), 792 | (10821, 75, '2023-01-08'), 793 | (10822, 82, '2023-01-08'), 794 | (10823, 46, '2023-01-09'), 795 | (10824, 24, '2023-01-09'), 796 | (10825, 17, '2023-01-09'), 797 | (10826, 7, '2023-01-12'), 798 | (10827, 9, '2023-01-12'), 799 | (10828, 64, '2023-01-13'), 800 | (10829, 38, '2023-01-13'), 801 | (10830, 81, '2023-01-13'), 802 | (10831, 70, '2023-01-14'), 803 | (10832, 41, '2023-01-14'), 804 | (10833, 56, '2023-01-15'), 805 | (10834, 81, '2023-01-15'), 806 | (10835, 1, '2023-01-15'), 807 | (10836, 20, '2023-01-16'), 808 | (10837, 5, '2023-01-16'), 809 | (10838, 47, '2023-01-19'), 810 | (10839, 81, '2023-01-19'), 811 | (10840, 47, '2023-01-19'), 812 | (10841, 76, '2023-01-20'), 813 | (10842, 80, '2023-01-20'), 814 | (10843, 84, '2023-01-21'), 815 | (10844, 59, '2023-01-21'), 816 | (10845, 63, '2023-01-21'), 817 | (10846, 76, '2023-01-22'), 818 | (10847, 71, '2023-01-22'), 819 | (10848, 16, '2023-01-23'), 820 | (10849, 39, '2023-01-23'), 821 | (10850, 84, '2023-01-23'), 822 | (10851, 67, '2023-01-26'), 823 | (10852, 65, '2023-01-26'), 824 | (10853, 6, '2023-01-27'), 825 | (10854, 20, '2023-01-27'), 826 | (10855, 55, '2023-01-27'), 827 | (10856, 3, '2023-01-28'), 828 | (10857, 5, '2023-01-28'), 829 | (10858, 40, '2023-01-29'), 830 | (10859, 25, '2023-01-29'), 831 | (10860, 26, '2023-01-29'), 832 | (10861, 89, '2023-01-30'), 833 | (10862, 44, '2023-01-30'), 834 | (10863, 35, '2023-02-02'), 835 | (10864, 4, '2023-02-02'), 836 | (10865, 63, '2023-02-02'), 837 | (10866, 5, '2023-02-03'), 838 | (10867, 48, '2023-02-03'), 839 | (10868, 62, '2023-02-04'), 840 | (10869, 72, '2023-02-04'), 841 | (10870, 91, '2023-02-04'), 842 | (10871, 9, '2023-02-05'), 843 | (10872, 30, '2023-02-05'), 844 | (10873, 90, '2023-02-06'), 845 | (10874, 30, '2023-02-06'), 846 | (10875, 5, '2023-02-06'), 847 | (10876, 9, '2023-02-09'), 848 | (10877, 67, '2023-02-09'), 849 | (10878, 63, '2023-02-10'), 850 | (10879, 90, '2023-02-10'), 851 | (10880, 24, '2023-02-10'), 852 | (10881, 12, '2023-02-11'), 853 | (10882, 71, '2023-02-11'), 854 | (10883, 48, '2023-02-12'), 855 | (10884, 45, '2023-02-12'), 856 | (10885, 76, '2023-02-12'), 857 | (10886, 34, '2023-02-13'), 858 | (10887, 29, '2023-02-13'), 859 | (10888, 30, '2023-02-16'), 860 | (10889, 65, '2023-02-16'), 861 | (10890, 18, '2023-02-16'), 862 | (10891, 44, '2023-02-17'), 863 | (10892, 50, '2023-02-17'), 864 | (10893, 39, '2023-02-18'), 865 | (10894, 71, '2023-02-18'), 866 | (10895, 20, '2023-02-18'), 867 | (10896, 50, '2023-02-19'), 868 | (10897, 37, '2023-02-19'), 869 | (10898, 54, '2023-02-20'), 870 | (10899, 46, '2023-02-20'), 871 | (10900, 88, '2023-02-20'), 872 | (10901, 35, '2023-02-23'), 873 | (10902, 24, '2023-02-23'), 874 | (10903, 34, '2023-02-24'), 875 | (10904, 89, '2023-02-24'), 876 | (10905, 88, '2023-02-24'), 877 | (10906, 91, '2023-02-25'), 878 | (10907, 74, '2023-02-25'), 879 | (10908, 66, '2023-02-26'), 880 | (10909, 70, '2023-02-26'), 881 | (10910, 90, '2023-02-26'), 882 | (10911, 30, '2023-02-26'), 883 | (10912, 37, '2023-02-26'), 884 | (10913, 62, '2023-02-26'), 885 | (10914, 62, '2023-02-27'), 886 | (10915, 80, '2023-02-27'), 887 | (10916, 64, '2023-02-27'), 888 | (10917, 69, '2023-03-02'), 889 | (10918, 10, '2023-03-02'), 890 | (10919, 47, '2023-03-02'), 891 | (10920, 4, '2023-03-03'), 892 | (10921, 83, '2023-03-03'), 893 | (10922, 34, '2023-03-03'), 894 | (10923, 41, '2023-03-03'), 895 | (10924, 5, '2023-03-04'), 896 | (10925, 34, '2023-03-04'), 897 | (10926, 2, '2023-03-04'), 898 | (10927, 40, '2023-03-05'), 899 | (10928, 29, '2023-03-05'), 900 | (10929, 25, '2023-03-05'), 901 | (10930, 76, '2023-03-06'), 902 | (10931, 68, '2023-03-06'), 903 | (10932, 9, '2023-03-06'), 904 | (10933, 38, '2023-03-06'), 905 | (10934, 44, '2023-03-09'), 906 | (10935, 88, '2023-03-09'), 907 | (10936, 32, '2023-03-09'), 908 | (10937, 12, '2023-03-10'), 909 | (10938, 63, '2023-03-10'), 910 | (10939, 49, '2023-03-10'), 911 | (10940, 9, '2023-03-11'), 912 | (10941, 71, '2023-03-11'), 913 | (10942, 66, '2023-03-11'), 914 | (10943, 11, '2023-03-11'), 915 | (10944, 10, '2023-03-12'), 916 | (10945, 52, '2023-03-12'), 917 | (10946, 83, '2023-03-12'), 918 | (10947, 11, '2023-03-13'), 919 | (10948, 30, '2023-03-13'), 920 | (10949, 10, '2023-03-13'), 921 | (10950, 49, '2023-03-16'), 922 | (10951, 68, '2023-03-16'), 923 | (10952, 1, '2023-03-16'), 924 | (10953, 4, '2023-03-16'), 925 | (10954, 47, '2023-03-17'), 926 | (10955, 24, '2023-03-17'), 927 | (10956, 6, '2023-03-17'), 928 | (10957, 35, '2023-03-18'), 929 | (10958, 54, '2023-03-18'), 930 | (10959, 31, '2023-03-18'), 931 | (10960, 35, '2023-03-19'), 932 | (10961, 62, '2023-03-19'), 933 | (10962, 63, '2023-03-19'), 934 | (10963, 28, '2023-03-19'), 935 | (10964, 74, '2023-03-20'), 936 | (10965, 55, '2023-03-20'), 937 | (10966, 14, '2023-03-20'), 938 | (10967, 79, '2023-03-23'), 939 | (10968, 20, '2023-03-23'), 940 | (10969, 15, '2023-03-23'), 941 | (10970, 8, '2023-03-24'), 942 | (10971, 26, '2023-03-24'), 943 | (10972, 40, '2023-03-24'), 944 | (10973, 40, '2023-03-24'), 945 | (10974, 75, '2023-03-25'), 946 | (10975, 10, '2023-03-25'), 947 | (10976, 35, '2023-03-25'), 948 | (10977, 24, '2023-03-26'), 949 | (10978, 50, '2023-03-26'), 950 | (10979, 20, '2023-03-26'), 951 | (10980, 24, '2023-03-27'), 952 | (10981, 34, '2023-03-27'), 953 | (10982, 10, '2023-03-27'), 954 | (10983, 71, '2023-03-27'), 955 | (10984, 71, '2023-03-30'), 956 | (10985, 37, '2023-03-30'), 957 | (10986, 54, '2023-03-30'), 958 | (10987, 19, '2023-03-31'), 959 | (10988, 65, '2023-03-31'), 960 | (10989, 61, '2023-03-31'), 961 | (10990, 20, '2023-04-01'), 962 | (10991, 63, '2023-04-01'), 963 | (10992, 77, '2023-04-01'), 964 | (10993, 24, '2023-04-01'), 965 | (10994, 83, '2023-04-02'), 966 | (10995, 58, '2023-04-02'), 967 | (10996, 63, '2023-04-02'), 968 | (10997, 46, '2023-04-03'), 969 | (10998, 91, '2023-04-03'), 970 | (10999, 56, '2023-04-03'), 971 | (11000, 65, '2023-04-06'), 972 | (11001, 24, '2023-04-06'), 973 | (11002, 71, '2023-04-06'), 974 | (11003, 78, '2023-04-06'), 975 | (11004, 50, '2023-04-07'), 976 | (11005, 90, '2023-04-07'), 977 | (11006, 32, '2023-04-07'), 978 | (11007, 60, '2023-04-08'), 979 | (11008, 20, '2023-04-08'), 980 | (11009, 30, '2023-04-08'), 981 | (11010, 66, '2023-04-09'), 982 | (11011, 1, '2023-04-09'), 983 | (11012, 25, '2023-04-09'), 984 | (11013, 69, '2023-04-09'), 985 | (11014, 47, '2023-04-10'), 986 | (11015, 70, '2023-04-10'), 987 | (11016, 4, '2023-04-10'), 988 | (11017, 20, '2023-04-13'), 989 | (11018, 48, '2023-04-13'), 990 | (11019, 64, '2023-04-13'), 991 | (11020, 56, '2023-04-14'), 992 | (11021, 63, '2023-04-14'), 993 | (11022, 34, '2023-04-14'), 994 | (11023, 11, '2023-04-14'), 995 | (11024, 19, '2023-04-15'), 996 | (11025, 87, '2023-04-15'), 997 | (11026, 27, '2023-04-15'), 998 | (11027, 10, '2023-04-16'), 999 | (11028, 39, '2023-04-16'), 1000 | (11029, 14, '2023-04-16'), 1001 | (11030, 71, '2023-04-17'), 1002 | (11031, 71, '2023-04-17'), 1003 | (11032, 89, '2023-04-17'), 1004 | (11033, 68, '2023-04-17'), 1005 | (11034, 55, '2023-04-20'), 1006 | (11035, 76, '2023-04-20'), 1007 | (11036, 17, '2023-04-20'), 1008 | (11037, 30, '2023-04-21'), 1009 | (11038, 76, '2023-04-21'), 1010 | (11039, 47, '2023-04-21'), 1011 | (11040, 32, '2023-04-22'), 1012 | (11041, 14, '2023-04-22'), 1013 | (11042, 15, '2023-04-22'), 1014 | (11043, 74, '2023-04-22'), 1015 | (11044, 91, '2023-04-23'), 1016 | (11045, 10, '2023-04-23'), 1017 | (11046, 86, '2023-04-23'), 1018 | (11047, 19, '2023-04-24'), 1019 | (11048, 10, '2023-04-24'), 1020 | (11049, 31, '2023-04-24'), 1021 | (11050, 24, '2023-04-27'), 1022 | (11051, 41, '2023-04-27'), 1023 | (11052, 34, '2023-04-27'), 1024 | (11053, 59, '2023-04-27'), 1025 | (11054, 12, '2023-04-28'), 1026 | (11055, 35, '2023-04-28'), 1027 | (11056, 19, '2023-04-28'), 1028 | (11057, 53, '2023-04-29'), 1029 | (11058, 6, '2023-04-29'), 1030 | (11059, 67, '2023-04-29'), 1031 | (11060, 27, '2023-04-30'), 1032 | (11061, 32, '2023-04-30'), 1033 | (11062, 66, '2023-04-30'), 1034 | (11063, 37, '2023-04-30'), 1035 | (11064, 71, '2023-05-01'), 1036 | (11065, 46, '2023-05-01'), 1037 | (11066, 89, '2023-05-01'), 1038 | (11067, 17, '2023-05-04'), 1039 | (11068, 62, '2023-05-04'), 1040 | (11069, 80, '2023-05-04'), 1041 | (11070, 44, '2023-05-05'), 1042 | (11071, 46, '2023-05-05'), 1043 | (11072, 20, '2023-05-05'), 1044 | (11073, 58, '2023-05-05'), 1045 | (11074, 73, '2023-05-06'), 1046 | (11075, 68, '2023-05-06'), 1047 | (11076, 9, '2023-05-06'), 1048 | (11077, 65, '2023-05-06'); 1049 | 1050 | CREATE TABLE order_details ( 1051 | order_detail_id SERIAL NOT NULL PRIMARY KEY, 1052 | order_id INT, 1053 | product_id INT, 1054 | quantity INT 1055 | ); 1056 | 1057 | INSERT INTO order_details (order_id, product_id, quantity) 1058 | VALUES 1059 | (10248, 11, 12), 1060 | (10248, 42, 10), 1061 | (10248, 72, 5), 1062 | (10249, 14, 9), 1063 | (10249, 51, 40), 1064 | (10250, 41, 10), 1065 | (10250, 51, 35), 1066 | (10250, 65, 15), 1067 | (10251, 22, 6), 1068 | (10251, 57, 15), 1069 | (10251, 65, 20), 1070 | (10252, 20, 40), 1071 | (10252, 33, 25), 1072 | (10252, 60, 40), 1073 | (10253, 31, 20), 1074 | (10253, 39, 42), 1075 | (10253, 49, 40), 1076 | (10254, 24, 15), 1077 | (10254, 55, 21), 1078 | (10254, 74, 21), 1079 | (10255, 2, 20), 1080 | (10255, 16, 35), 1081 | (10255, 36, 25), 1082 | (10255, 59, 30), 1083 | (10256, 53, 15), 1084 | (10256, 77, 12), 1085 | (10257, 27, 25), 1086 | (10257, 39, 6), 1087 | (10257, 77, 15), 1088 | (10258, 2, 50), 1089 | (10258, 5, 65), 1090 | (10258, 32, 6), 1091 | (10259, 21, 10), 1092 | (10259, 37, 1), 1093 | (10260, 41, 16), 1094 | (10260, 57, 50), 1095 | (10260, 62, 15), 1096 | (10260, 70, 21), 1097 | (10261, 21, 20), 1098 | (10261, 35, 20), 1099 | (10262, 5, 12), 1100 | (10262, 7, 15), 1101 | (10262, 56, 2), 1102 | (10263, 16, 60), 1103 | (10263, 24, 28), 1104 | (10263, 30, 60), 1105 | (10263, 74, 36), 1106 | (10264, 2, 35), 1107 | (10264, 41, 25), 1108 | (10265, 17, 30), 1109 | (10265, 70, 20), 1110 | (10266, 12, 12), 1111 | (10267, 40, 50), 1112 | (10267, 59, 70), 1113 | (10267, 76, 15), 1114 | (10268, 29, 10), 1115 | (10268, 72, 4), 1116 | (10269, 33, 60), 1117 | (10269, 72, 20), 1118 | (10270, 36, 30), 1119 | (10270, 43, 25), 1120 | (10271, 33, 24), 1121 | (10272, 20, 6), 1122 | (10272, 31, 40), 1123 | (10272, 72, 24), 1124 | (10273, 10, 24), 1125 | (10273, 31, 15), 1126 | (10273, 33, 20), 1127 | (10273, 40, 60), 1128 | (10273, 76, 33), 1129 | (10274, 71, 20), 1130 | (10274, 72, 7), 1131 | (10275, 24, 12), 1132 | (10275, 59, 6), 1133 | (10276, 10, 15), 1134 | (10276, 13, 10), 1135 | (10277, 28, 20), 1136 | (10277, 62, 12), 1137 | (10278, 44, 16), 1138 | (10278, 59, 15), 1139 | (10278, 63, 8), 1140 | (10278, 73, 25), 1141 | (10279, 17, 15), 1142 | (10280, 24, 12), 1143 | (10280, 55, 20), 1144 | (10280, 75, 30), 1145 | (10281, 19, 1), 1146 | (10281, 24, 6), 1147 | (10281, 35, 4), 1148 | (10282, 30, 6), 1149 | (10282, 57, 2), 1150 | (10283, 15, 20), 1151 | (10283, 19, 18), 1152 | (10283, 60, 35), 1153 | (10283, 72, 3), 1154 | (10284, 27, 15), 1155 | (10284, 44, 21), 1156 | (10284, 60, 20), 1157 | (10284, 67, 5), 1158 | (10285, 1, 45), 1159 | (10285, 40, 40), 1160 | (10285, 53, 36), 1161 | (10286, 35, 100), 1162 | (10286, 62, 40), 1163 | (10287, 16, 40), 1164 | (10287, 34, 20), 1165 | (10287, 46, 15), 1166 | (10288, 54, 10), 1167 | (10288, 68, 3), 1168 | (10289, 3, 30), 1169 | (10289, 64, 9), 1170 | (10290, 5, 20), 1171 | (10290, 29, 15), 1172 | (10290, 49, 15), 1173 | (10290, 77, 10), 1174 | (10291, 13, 20), 1175 | (10291, 44, 24), 1176 | (10291, 51, 2), 1177 | (10292, 20, 20), 1178 | (10293, 18, 12), 1179 | (10293, 24, 10), 1180 | (10293, 63, 5), 1181 | (10293, 75, 6), 1182 | (10294, 1, 18), 1183 | (10294, 17, 15), 1184 | (10294, 43, 15), 1185 | (10294, 60, 21), 1186 | (10294, 75, 6), 1187 | (10295, 56, 4), 1188 | (10296, 11, 12), 1189 | (10296, 16, 30), 1190 | (10296, 69, 15), 1191 | (10297, 39, 60), 1192 | (10297, 72, 20), 1193 | (10298, 2, 40), 1194 | (10298, 36, 40), 1195 | (10298, 59, 30), 1196 | (10298, 62, 15), 1197 | (10299, 19, 15), 1198 | (10299, 70, 20), 1199 | (10300, 66, 30), 1200 | (10300, 68, 20), 1201 | (10301, 40, 10), 1202 | (10301, 56, 20), 1203 | (10302, 17, 40), 1204 | (10302, 28, 28), 1205 | (10302, 43, 12), 1206 | (10303, 40, 40), 1207 | (10303, 65, 30), 1208 | (10303, 68, 15), 1209 | (10304, 49, 30), 1210 | (10304, 59, 10), 1211 | (10304, 71, 2), 1212 | (10305, 18, 25), 1213 | (10305, 29, 25), 1214 | (10305, 39, 30), 1215 | (10306, 30, 10), 1216 | (10306, 53, 10), 1217 | (10306, 54, 5), 1218 | (10307, 62, 10), 1219 | (10307, 68, 3), 1220 | (10308, 69, 1), 1221 | (10308, 70, 5), 1222 | (10309, 4, 20), 1223 | (10309, 6, 30), 1224 | (10309, 42, 2), 1225 | (10309, 43, 20), 1226 | (10309, 71, 3), 1227 | (10310, 16, 10), 1228 | (10310, 62, 5), 1229 | (10311, 42, 6), 1230 | (10311, 69, 7), 1231 | (10312, 28, 4), 1232 | (10312, 43, 24), 1233 | (10312, 53, 20), 1234 | (10312, 75, 10), 1235 | (10313, 36, 12), 1236 | (10314, 32, 40), 1237 | (10314, 58, 30), 1238 | (10314, 62, 25), 1239 | (10315, 34, 14), 1240 | (10315, 70, 30), 1241 | (10316, 41, 10), 1242 | (10316, 62, 70), 1243 | (10317, 1, 20), 1244 | (10318, 41, 20), 1245 | (10318, 76, 6), 1246 | (10319, 17, 8), 1247 | (10319, 28, 14), 1248 | (10319, 76, 30), 1249 | (10320, 71, 30), 1250 | (10321, 35, 10), 1251 | (10322, 52, 20), 1252 | (10323, 15, 5), 1253 | (10323, 25, 4), 1254 | (10323, 39, 4), 1255 | (10324, 16, 21), 1256 | (10324, 35, 70), 1257 | (10324, 46, 30), 1258 | (10324, 59, 40), 1259 | (10324, 63, 80), 1260 | (10325, 6, 6), 1261 | (10325, 13, 12), 1262 | (10325, 14, 9), 1263 | (10325, 31, 4), 1264 | (10325, 72, 40), 1265 | (10326, 4, 24), 1266 | (10326, 57, 16), 1267 | (10326, 75, 50), 1268 | (10327, 2, 25), 1269 | (10327, 11, 50), 1270 | (10327, 30, 35), 1271 | (10327, 58, 30), 1272 | (10328, 59, 9), 1273 | (10328, 65, 40), 1274 | (10328, 68, 10), 1275 | (10329, 19, 10), 1276 | (10329, 30, 8), 1277 | (10329, 38, 20), 1278 | (10329, 56, 12), 1279 | (10330, 26, 50), 1280 | (10330, 72, 25), 1281 | (10331, 54, 15), 1282 | (10332, 18, 40), 1283 | (10332, 42, 10), 1284 | (10332, 47, 16), 1285 | (10333, 14, 10), 1286 | (10333, 21, 10), 1287 | (10333, 71, 40), 1288 | (10334, 52, 8), 1289 | (10334, 68, 10), 1290 | (10335, 2, 7), 1291 | (10335, 31, 25), 1292 | (10335, 32, 6), 1293 | (10335, 51, 48), 1294 | (10336, 4, 18), 1295 | (10337, 23, 40), 1296 | (10337, 26, 24), 1297 | (10337, 36, 20), 1298 | (10337, 37, 28), 1299 | (10337, 72, 25), 1300 | (10338, 17, 20), 1301 | (10338, 30, 15), 1302 | (10339, 4, 10), 1303 | (10339, 17, 70), 1304 | (10339, 62, 28), 1305 | (10340, 18, 20), 1306 | (10340, 41, 12), 1307 | (10340, 43, 40), 1308 | (10341, 33, 8), 1309 | (10341, 59, 9), 1310 | (10342, 2, 24), 1311 | (10342, 31, 56), 1312 | (10342, 36, 40), 1313 | (10342, 55, 40), 1314 | (10343, 64, 50), 1315 | (10343, 68, 4), 1316 | (10343, 76, 15), 1317 | (10344, 4, 35), 1318 | (10344, 8, 70), 1319 | (10345, 8, 70), 1320 | (10345, 19, 80), 1321 | (10345, 42, 9), 1322 | (10346, 17, 36), 1323 | (10346, 56, 20), 1324 | (10347, 25, 10), 1325 | (10347, 39, 50), 1326 | (10347, 40, 4), 1327 | (10347, 75, 6), 1328 | (10348, 1, 15), 1329 | (10348, 23, 25), 1330 | (10349, 54, 24), 1331 | (10350, 50, 15), 1332 | (10350, 69, 18), 1333 | (10351, 38, 20), 1334 | (10351, 41, 13), 1335 | (10351, 44, 77), 1336 | (10351, 65, 10), 1337 | (10352, 24, 10), 1338 | (10352, 54, 20), 1339 | (10353, 11, 12), 1340 | (10353, 38, 50), 1341 | (10354, 1, 12), 1342 | (10354, 29, 4), 1343 | (10355, 24, 25), 1344 | (10355, 57, 25), 1345 | (10356, 31, 30), 1346 | (10356, 55, 12), 1347 | (10356, 69, 20), 1348 | (10357, 10, 30), 1349 | (10357, 26, 16), 1350 | (10357, 60, 8), 1351 | (10358, 24, 10), 1352 | (10358, 34, 10), 1353 | (10358, 36, 20), 1354 | (10359, 16, 56), 1355 | (10359, 31, 70), 1356 | (10359, 60, 80), 1357 | (10360, 28, 30), 1358 | (10360, 29, 35), 1359 | (10360, 38, 10), 1360 | (10360, 49, 35), 1361 | (10360, 54, 28), 1362 | (10361, 39, 54), 1363 | (10361, 60, 55), 1364 | (10362, 25, 50), 1365 | (10362, 51, 20), 1366 | (10362, 54, 24), 1367 | (10363, 31, 20), 1368 | (10363, 75, 12), 1369 | (10363, 76, 12), 1370 | (10364, 69, 30), 1371 | (10364, 71, 5), 1372 | (10365, 11, 24), 1373 | (10366, 65, 5), 1374 | (10366, 77, 5), 1375 | (10367, 34, 36), 1376 | (10367, 54, 18), 1377 | (10367, 65, 15), 1378 | (10367, 77, 7), 1379 | (10368, 21, 5), 1380 | (10368, 28, 13), 1381 | (10368, 57, 25), 1382 | (10368, 64, 35), 1383 | (10369, 29, 20), 1384 | (10369, 56, 18), 1385 | (10370, 1, 15), 1386 | (10370, 64, 30), 1387 | (10370, 74, 20), 1388 | (10371, 36, 6), 1389 | (10372, 20, 12), 1390 | (10372, 38, 40), 1391 | (10372, 60, 70), 1392 | (10372, 72, 42), 1393 | (10373, 58, 80), 1394 | (10373, 71, 50), 1395 | (10374, 31, 30), 1396 | (10374, 58, 15), 1397 | (10375, 14, 15), 1398 | (10375, 54, 10), 1399 | (10376, 31, 42), 1400 | (10377, 28, 20), 1401 | (10377, 39, 20), 1402 | (10378, 71, 6), 1403 | (10379, 41, 8), 1404 | (10379, 63, 16), 1405 | (10379, 65, 20), 1406 | (10380, 30, 18), 1407 | (10380, 53, 20), 1408 | (10380, 60, 6), 1409 | (10380, 70, 30), 1410 | (10381, 74, 14), 1411 | (10382, 5, 32), 1412 | (10382, 18, 9), 1413 | (10382, 29, 14), 1414 | (10382, 33, 60), 1415 | (10382, 74, 50), 1416 | (10383, 13, 20), 1417 | (10383, 50, 15), 1418 | (10383, 56, 20), 1419 | (10384, 20, 28), 1420 | (10384, 60, 15), 1421 | (10385, 7, 10), 1422 | (10385, 60, 20), 1423 | (10385, 68, 8), 1424 | (10386, 24, 15), 1425 | (10386, 34, 10), 1426 | (10387, 24, 15), 1427 | (10387, 28, 6), 1428 | (10387, 59, 12), 1429 | (10387, 71, 15), 1430 | (10388, 45, 15), 1431 | (10388, 52, 20), 1432 | (10388, 53, 40), 1433 | (10389, 10, 16), 1434 | (10389, 55, 15), 1435 | (10389, 62, 20), 1436 | (10389, 70, 30), 1437 | (10390, 31, 60), 1438 | (10390, 35, 40), 1439 | (10390, 46, 45), 1440 | (10390, 72, 24), 1441 | (10391, 13, 18), 1442 | (10392, 69, 50), 1443 | (10393, 2, 25), 1444 | (10393, 14, 42), 1445 | (10393, 25, 7), 1446 | (10393, 26, 70), 1447 | (10393, 31, 32), 1448 | (10394, 13, 10), 1449 | (10394, 62, 10), 1450 | (10395, 46, 28), 1451 | (10395, 53, 70), 1452 | (10395, 69, 8), 1453 | (10396, 23, 40), 1454 | (10396, 71, 60), 1455 | (10396, 72, 21), 1456 | (10397, 21, 10), 1457 | (10397, 51, 18), 1458 | (10398, 35, 30), 1459 | (10398, 55, 120), 1460 | (10399, 68, 60), 1461 | (10399, 71, 30), 1462 | (10399, 76, 35), 1463 | (10399, 77, 14), 1464 | (10400, 29, 21), 1465 | (10400, 35, 35), 1466 | (10400, 49, 30), 1467 | (10401, 30, 18), 1468 | (10401, 56, 70), 1469 | (10401, 65, 20), 1470 | (10401, 71, 60), 1471 | (10402, 23, 60), 1472 | (10402, 63, 65), 1473 | (10403, 16, 21), 1474 | (10403, 48, 70), 1475 | (10404, 26, 30), 1476 | (10404, 42, 40), 1477 | (10404, 49, 30), 1478 | (10405, 3, 50), 1479 | (10406, 1, 10), 1480 | (10406, 21, 30), 1481 | (10406, 28, 42), 1482 | (10406, 36, 5), 1483 | (10406, 40, 2), 1484 | (10407, 11, 30), 1485 | (10407, 69, 15), 1486 | (10407, 71, 15), 1487 | (10408, 37, 10), 1488 | (10408, 54, 6), 1489 | (10408, 62, 35), 1490 | (10409, 14, 12), 1491 | (10409, 21, 12), 1492 | (10410, 33, 49), 1493 | (10410, 59, 16), 1494 | (10411, 41, 25), 1495 | (10411, 44, 40), 1496 | (10411, 59, 9), 1497 | (10412, 14, 20), 1498 | (10413, 1, 24), 1499 | (10413, 62, 40), 1500 | (10413, 76, 14), 1501 | (10414, 19, 18), 1502 | (10414, 33, 50), 1503 | (10415, 17, 2), 1504 | (10415, 33, 20), 1505 | (10416, 19, 20), 1506 | (10416, 53, 10), 1507 | (10416, 57, 20), 1508 | (10417, 38, 50), 1509 | (10417, 46, 2), 1510 | (10417, 68, 36), 1511 | (10417, 77, 35), 1512 | (10418, 2, 60), 1513 | (10418, 47, 55), 1514 | (10418, 61, 16), 1515 | (10418, 74, 15), 1516 | (10419, 60, 60), 1517 | (10419, 69, 20), 1518 | (10420, 9, 20), 1519 | (10420, 13, 2), 1520 | (10420, 70, 8), 1521 | (10420, 73, 20), 1522 | (10421, 19, 4), 1523 | (10421, 26, 30), 1524 | (10421, 53, 15), 1525 | (10421, 77, 10), 1526 | (10422, 26, 2), 1527 | (10423, 31, 14), 1528 | (10423, 59, 20), 1529 | (10424, 35, 60), 1530 | (10424, 38, 49), 1531 | (10424, 68, 30), 1532 | (10425, 55, 10), 1533 | (10425, 76, 20), 1534 | (10426, 56, 5), 1535 | (10426, 64, 7), 1536 | (10427, 14, 35), 1537 | (10428, 46, 20), 1538 | (10429, 50, 40), 1539 | (10429, 63, 35), 1540 | (10430, 17, 45), 1541 | (10430, 21, 50), 1542 | (10430, 56, 30), 1543 | (10430, 59, 70), 1544 | (10431, 17, 50), 1545 | (10431, 40, 50), 1546 | (10431, 47, 30), 1547 | (10432, 26, 10), 1548 | (10432, 54, 40), 1549 | (10433, 56, 28), 1550 | (10434, 11, 6), 1551 | (10434, 76, 18), 1552 | (10435, 2, 10), 1553 | (10435, 22, 12), 1554 | (10435, 72, 10), 1555 | (10436, 46, 5), 1556 | (10436, 56, 40), 1557 | (10436, 64, 30), 1558 | (10436, 75, 24), 1559 | (10437, 53, 15), 1560 | (10438, 19, 15), 1561 | (10438, 34, 20), 1562 | (10438, 57, 15), 1563 | (10439, 12, 15), 1564 | (10439, 16, 16), 1565 | (10439, 64, 6), 1566 | (10439, 74, 30), 1567 | (10440, 2, 45), 1568 | (10440, 16, 49), 1569 | (10440, 29, 24), 1570 | (10440, 61, 90), 1571 | (10441, 27, 50), 1572 | (10442, 11, 30), 1573 | (10442, 54, 80), 1574 | (10442, 66, 60), 1575 | (10443, 11, 6), 1576 | (10443, 28, 12), 1577 | (10444, 17, 10), 1578 | (10444, 26, 15), 1579 | (10444, 35, 8), 1580 | (10444, 41, 30), 1581 | (10445, 39, 6), 1582 | (10445, 54, 15), 1583 | (10446, 19, 12), 1584 | (10446, 24, 20), 1585 | (10446, 31, 3), 1586 | (10446, 52, 15), 1587 | (10447, 19, 40), 1588 | (10447, 65, 35), 1589 | (10447, 71, 2), 1590 | (10448, 26, 6), 1591 | (10448, 40, 20), 1592 | (10449, 10, 14), 1593 | (10449, 52, 20), 1594 | (10449, 62, 35), 1595 | (10450, 10, 20), 1596 | (10450, 54, 6), 1597 | (10451, 55, 120), 1598 | (10451, 64, 35), 1599 | (10451, 65, 28), 1600 | (10451, 77, 55), 1601 | (10452, 28, 15), 1602 | (10452, 44, 100), 1603 | (10453, 48, 15), 1604 | (10453, 70, 25), 1605 | (10454, 16, 20), 1606 | (10454, 33, 20), 1607 | (10454, 46, 10), 1608 | (10455, 39, 20), 1609 | (10455, 53, 50), 1610 | (10455, 61, 25), 1611 | (10455, 71, 30), 1612 | (10456, 21, 40), 1613 | (10456, 49, 21), 1614 | (10457, 59, 36), 1615 | (10458, 26, 30), 1616 | (10458, 28, 30), 1617 | (10458, 43, 20), 1618 | (10458, 56, 15), 1619 | (10458, 71, 50), 1620 | (10459, 7, 16), 1621 | (10459, 46, 20), 1622 | (10459, 72, 40), 1623 | (10460, 68, 21), 1624 | (10460, 75, 4), 1625 | (10461, 21, 40), 1626 | (10461, 30, 28), 1627 | (10461, 55, 60), 1628 | (10462, 13, 1), 1629 | (10462, 23, 21), 1630 | (10463, 19, 21), 1631 | (10463, 42, 50), 1632 | (10464, 4, 16), 1633 | (10464, 43, 3), 1634 | (10464, 56, 30), 1635 | (10464, 60, 20), 1636 | (10465, 24, 25), 1637 | (10465, 29, 18), 1638 | (10465, 40, 20), 1639 | (10465, 45, 30), 1640 | (10465, 50, 25), 1641 | (10466, 11, 10), 1642 | (10466, 46, 5), 1643 | (10467, 24, 28), 1644 | (10467, 25, 12), 1645 | (10468, 30, 8), 1646 | (10468, 43, 15), 1647 | (10469, 2, 40), 1648 | (10469, 16, 35), 1649 | (10469, 44, 2), 1650 | (10470, 18, 30), 1651 | (10470, 23, 15), 1652 | (10470, 64, 8), 1653 | (10471, 7, 30), 1654 | (10471, 56, 20), 1655 | (10472, 24, 80), 1656 | (10472, 51, 18), 1657 | (10473, 33, 12), 1658 | (10473, 71, 12), 1659 | (10474, 14, 12), 1660 | (10474, 28, 18), 1661 | (10474, 40, 21), 1662 | (10474, 75, 10), 1663 | (10475, 31, 35), 1664 | (10475, 66, 60), 1665 | (10475, 76, 42), 1666 | (10476, 55, 2), 1667 | (10476, 70, 12), 1668 | (10477, 1, 15), 1669 | (10477, 21, 21), 1670 | (10477, 39, 20), 1671 | (10478, 10, 20), 1672 | (10479, 38, 30), 1673 | (10479, 53, 28), 1674 | (10479, 59, 60), 1675 | (10479, 64, 30), 1676 | (10480, 47, 30), 1677 | (10480, 59, 12), 1678 | (10481, 49, 24), 1679 | (10481, 60, 40), 1680 | (10482, 40, 10), 1681 | (10483, 34, 35), 1682 | (10483, 77, 30), 1683 | (10484, 21, 14), 1684 | (10484, 40, 10), 1685 | (10484, 51, 3), 1686 | (10485, 2, 20), 1687 | (10485, 3, 20), 1688 | (10485, 55, 30), 1689 | (10485, 70, 60), 1690 | (10486, 11, 5), 1691 | (10486, 51, 25), 1692 | (10486, 74, 16), 1693 | (10487, 19, 5), 1694 | (10487, 26, 30), 1695 | (10487, 54, 24), 1696 | (10488, 59, 30), 1697 | (10488, 73, 20), 1698 | (10489, 11, 15), 1699 | (10489, 16, 18), 1700 | (10490, 59, 60), 1701 | (10490, 68, 30), 1702 | (10490, 75, 36), 1703 | (10491, 44, 15), 1704 | (10491, 77, 7), 1705 | (10492, 25, 60), 1706 | (10492, 42, 20), 1707 | (10493, 65, 15), 1708 | (10493, 66, 10), 1709 | (10493, 69, 10), 1710 | (10494, 56, 30), 1711 | (10495, 23, 10), 1712 | (10495, 41, 20), 1713 | (10495, 77, 5), 1714 | (10496, 31, 20), 1715 | (10497, 56, 14), 1716 | (10497, 72, 25), 1717 | (10497, 77, 25), 1718 | (10498, 24, 14), 1719 | (10498, 40, 5), 1720 | (10498, 42, 30), 1721 | (10499, 28, 20), 1722 | (10499, 49, 25), 1723 | (10500, 15, 12), 1724 | (10500, 28, 8), 1725 | (10501, 54, 20), 1726 | (10502, 45, 21), 1727 | (10502, 53, 6), 1728 | (10502, 67, 30), 1729 | (10503, 14, 70), 1730 | (10503, 65, 20), 1731 | (10504, 2, 12), 1732 | (10504, 21, 12), 1733 | (10504, 53, 10), 1734 | (10504, 61, 25), 1735 | (10505, 62, 3), 1736 | (10506, 25, 18), 1737 | (10506, 70, 14), 1738 | (10507, 43, 15), 1739 | (10507, 48, 15), 1740 | (10508, 13, 10), 1741 | (10508, 39, 10), 1742 | (10509, 28, 3), 1743 | (10510, 29, 36), 1744 | (10510, 75, 36), 1745 | (10511, 4, 50), 1746 | (10511, 7, 50), 1747 | (10511, 8, 10), 1748 | (10512, 24, 10), 1749 | (10512, 46, 9), 1750 | (10512, 47, 6), 1751 | (10512, 60, 12), 1752 | (10513, 21, 40), 1753 | (10513, 32, 50), 1754 | (10513, 61, 15), 1755 | (10514, 20, 39), 1756 | (10514, 28, 35), 1757 | (10514, 56, 70), 1758 | (10514, 65, 39), 1759 | (10514, 75, 50), 1760 | (10515, 9, 16), 1761 | (10515, 16, 50), 1762 | (10515, 27, 120), 1763 | (10515, 33, 16), 1764 | (10515, 60, 84), 1765 | (10516, 18, 25), 1766 | (10516, 41, 80), 1767 | (10516, 42, 20), 1768 | (10517, 52, 6), 1769 | (10517, 59, 4), 1770 | (10517, 70, 6), 1771 | (10518, 24, 5), 1772 | (10518, 38, 15), 1773 | (10518, 44, 9), 1774 | (10519, 10, 16), 1775 | (10519, 56, 40), 1776 | (10519, 60, 10), 1777 | (10520, 24, 8), 1778 | (10520, 53, 5), 1779 | (10521, 35, 3), 1780 | (10521, 41, 10), 1781 | (10521, 68, 6), 1782 | (10522, 1, 40), 1783 | (10522, 8, 24), 1784 | (10522, 30, 20), 1785 | (10522, 40, 25), 1786 | (10523, 17, 25), 1787 | (10523, 20, 15), 1788 | (10523, 37, 18), 1789 | (10523, 41, 6), 1790 | (10524, 10, 2), 1791 | (10524, 30, 10), 1792 | (10524, 43, 60), 1793 | (10524, 54, 15), 1794 | (10525, 36, 30), 1795 | (10525, 40, 15), 1796 | (10526, 1, 8), 1797 | (10526, 13, 10), 1798 | (10526, 56, 30), 1799 | (10527, 4, 50), 1800 | (10527, 36, 30), 1801 | (10528, 11, 3), 1802 | (10528, 33, 8), 1803 | (10528, 72, 9), 1804 | (10529, 55, 14), 1805 | (10529, 68, 20), 1806 | (10529, 69, 10), 1807 | (10530, 17, 40), 1808 | (10530, 43, 25), 1809 | (10530, 61, 20), 1810 | (10530, 76, 50), 1811 | (10531, 59, 2), 1812 | (10532, 30, 15), 1813 | (10532, 66, 24), 1814 | (10533, 4, 50), 1815 | (10533, 72, 24), 1816 | (10533, 73, 24), 1817 | (10534, 30, 10), 1818 | (10534, 40, 10), 1819 | (10534, 54, 10), 1820 | (10535, 11, 50), 1821 | (10535, 40, 10), 1822 | (10535, 57, 5), 1823 | (10535, 59, 15), 1824 | (10536, 12, 15), 1825 | (10536, 31, 20), 1826 | (10536, 33, 30), 1827 | (10536, 60, 35), 1828 | (10537, 31, 30), 1829 | (10537, 51, 6), 1830 | (10537, 58, 20), 1831 | (10537, 72, 21), 1832 | (10537, 73, 9), 1833 | (10538, 70, 7), 1834 | (10538, 72, 1), 1835 | (10539, 13, 8), 1836 | (10539, 21, 15), 1837 | (10539, 33, 15), 1838 | (10539, 49, 6), 1839 | (10540, 3, 60), 1840 | (10540, 26, 40), 1841 | (10540, 38, 30), 1842 | (10540, 68, 35), 1843 | (10541, 24, 35), 1844 | (10541, 38, 4), 1845 | (10541, 65, 36), 1846 | (10541, 71, 9), 1847 | (10542, 11, 15), 1848 | (10542, 54, 24), 1849 | (10543, 12, 30), 1850 | (10543, 23, 70), 1851 | (10544, 28, 7), 1852 | (10544, 67, 7), 1853 | (10545, 11, 10), 1854 | (10546, 7, 10), 1855 | (10546, 35, 30), 1856 | (10546, 62, 40), 1857 | (10547, 32, 24), 1858 | (10547, 36, 60), 1859 | (10548, 34, 10), 1860 | (10548, 41, 14), 1861 | (10549, 31, 55), 1862 | (10549, 45, 100), 1863 | (10549, 51, 48), 1864 | (10550, 17, 8), 1865 | (10550, 19, 10), 1866 | (10550, 21, 6), 1867 | (10550, 61, 10), 1868 | (10551, 16, 40), 1869 | (10551, 35, 20), 1870 | (10551, 44, 40), 1871 | (10552, 69, 18), 1872 | (10552, 75, 30), 1873 | (10553, 11, 15), 1874 | (10553, 16, 14), 1875 | (10553, 22, 24), 1876 | (10553, 31, 30), 1877 | (10553, 35, 6), 1878 | (10554, 16, 30), 1879 | (10554, 23, 20), 1880 | (10554, 62, 20), 1881 | (10554, 77, 10), 1882 | (10555, 14, 30), 1883 | (10555, 19, 35), 1884 | (10555, 24, 18), 1885 | (10555, 51, 20), 1886 | (10555, 56, 40), 1887 | (10556, 72, 24), 1888 | (10557, 64, 30), 1889 | (10557, 75, 20), 1890 | (10558, 47, 25), 1891 | (10558, 51, 20), 1892 | (10558, 52, 30), 1893 | (10558, 53, 18), 1894 | (10558, 73, 3), 1895 | (10559, 41, 12), 1896 | (10559, 55, 18), 1897 | (10560, 30, 20), 1898 | (10560, 62, 15), 1899 | (10561, 44, 10), 1900 | (10561, 51, 50), 1901 | (10562, 33, 20), 1902 | (10562, 62, 10), 1903 | (10563, 36, 25), 1904 | (10563, 52, 70), 1905 | (10564, 17, 16), 1906 | (10564, 31, 6), 1907 | (10564, 55, 25), 1908 | (10565, 24, 25), 1909 | (10565, 64, 18), 1910 | (10566, 11, 35), 1911 | (10566, 18, 18), 1912 | (10566, 76, 10), 1913 | (10567, 31, 60), 1914 | (10567, 51, 3), 1915 | (10567, 59, 40), 1916 | (10568, 10, 5), 1917 | (10569, 31, 35), 1918 | (10569, 76, 30), 1919 | (10570, 11, 15), 1920 | (10570, 56, 60), 1921 | (10571, 14, 11), 1922 | (10571, 42, 28), 1923 | (10572, 16, 12), 1924 | (10572, 32, 10), 1925 | (10572, 40, 50), 1926 | (10572, 75, 15), 1927 | (10573, 17, 18), 1928 | (10573, 34, 40), 1929 | (10573, 53, 25), 1930 | (10574, 33, 14), 1931 | (10574, 40, 2), 1932 | (10574, 62, 10), 1933 | (10574, 64, 6), 1934 | (10575, 59, 12), 1935 | (10575, 63, 6), 1936 | (10575, 72, 30), 1937 | (10575, 76, 10), 1938 | (10576, 1, 10), 1939 | (10576, 31, 20), 1940 | (10576, 44, 21), 1941 | (10577, 39, 10), 1942 | (10577, 75, 20), 1943 | (10577, 77, 18), 1944 | (10578, 35, 20), 1945 | (10578, 57, 6), 1946 | (10579, 15, 10), 1947 | (10579, 75, 21), 1948 | (10580, 14, 15), 1949 | (10580, 41, 9), 1950 | (10580, 65, 30), 1951 | (10581, 75, 50), 1952 | (10582, 57, 4), 1953 | (10582, 76, 14), 1954 | (10583, 29, 10), 1955 | (10583, 60, 24), 1956 | (10583, 69, 10), 1957 | (10584, 31, 50), 1958 | (10585, 47, 15), 1959 | (10586, 52, 4), 1960 | (10587, 26, 6), 1961 | (10587, 35, 20), 1962 | (10587, 77, 20), 1963 | (10588, 18, 40), 1964 | (10588, 42, 100), 1965 | (10589, 35, 4), 1966 | (10590, 1, 20), 1967 | (10590, 77, 60), 1968 | (10591, 3, 14), 1969 | (10591, 7, 10), 1970 | (10591, 54, 50), 1971 | (10592, 15, 25), 1972 | (10592, 26, 5), 1973 | (10593, 20, 21), 1974 | (10593, 69, 20), 1975 | (10593, 76, 4), 1976 | (10594, 52, 24), 1977 | (10594, 58, 30), 1978 | (10595, 35, 30), 1979 | (10595, 61, 120), 1980 | (10595, 69, 65), 1981 | (10596, 56, 5), 1982 | (10596, 63, 24), 1983 | (10596, 75, 30), 1984 | (10597, 24, 35), 1985 | (10597, 57, 20), 1986 | (10597, 65, 12), 1987 | (10598, 27, 50), 1988 | (10598, 71, 9), 1989 | (10599, 62, 10), 1990 | (10600, 54, 4), 1991 | (10600, 73, 30), 1992 | (10601, 13, 60), 1993 | (10601, 59, 35), 1994 | (10602, 77, 5), 1995 | (10603, 22, 48), 1996 | (10603, 49, 25), 1997 | (10604, 48, 6), 1998 | (10604, 76, 10), 1999 | (10605, 16, 30), 2000 | (10605, 59, 20), 2001 | (10605, 60, 70), 2002 | (10605, 71, 15), 2003 | (10606, 4, 20), 2004 | (10606, 55, 20), 2005 | (10606, 62, 10), 2006 | (10607, 7, 45), 2007 | (10607, 17, 100), 2008 | (10607, 33, 14), 2009 | (10607, 40, 42), 2010 | (10607, 72, 12), 2011 | (10608, 56, 28), 2012 | (10609, 1, 3), 2013 | (10609, 10, 10), 2014 | (10609, 21, 6), 2015 | (10610, 36, 21), 2016 | (10611, 1, 6), 2017 | (10611, 2, 10), 2018 | (10611, 60, 15), 2019 | (10612, 10, 70), 2020 | (10612, 36, 55), 2021 | (10612, 49, 18), 2022 | (10612, 60, 40), 2023 | (10612, 76, 80), 2024 | (10613, 13, 8), 2025 | (10613, 75, 40), 2026 | (10614, 11, 14), 2027 | (10614, 21, 8), 2028 | (10614, 39, 5), 2029 | (10615, 55, 5), 2030 | (10616, 38, 15), 2031 | (10616, 56, 14), 2032 | (10616, 70, 15), 2033 | (10616, 71, 15), 2034 | (10617, 59, 30), 2035 | (10618, 6, 70), 2036 | (10618, 56, 20), 2037 | (10618, 68, 15), 2038 | (10619, 21, 42), 2039 | (10619, 22, 40), 2040 | (10620, 24, 5), 2041 | (10620, 52, 5), 2042 | (10621, 19, 5), 2043 | (10621, 23, 10), 2044 | (10621, 70, 20), 2045 | (10621, 71, 15), 2046 | (10622, 2, 20), 2047 | (10622, 68, 18), 2048 | (10623, 14, 21), 2049 | (10623, 19, 15), 2050 | (10623, 21, 25), 2051 | (10623, 24, 3), 2052 | (10623, 35, 30), 2053 | (10624, 28, 10), 2054 | (10624, 29, 6), 2055 | (10624, 44, 10), 2056 | (10625, 14, 3), 2057 | (10625, 42, 5), 2058 | (10625, 60, 10), 2059 | (10626, 53, 12), 2060 | (10626, 60, 20), 2061 | (10626, 71, 20), 2062 | (10627, 62, 15), 2063 | (10627, 73, 35), 2064 | (10628, 1, 25), 2065 | (10629, 29, 20), 2066 | (10629, 64, 9), 2067 | (10630, 55, 12), 2068 | (10630, 76, 35), 2069 | (10631, 75, 8), 2070 | (10632, 2, 30), 2071 | (10632, 33, 20), 2072 | (10633, 12, 36), 2073 | (10633, 13, 13), 2074 | (10633, 26, 35), 2075 | (10633, 62, 80), 2076 | (10634, 7, 35), 2077 | (10634, 18, 50), 2078 | (10634, 51, 15), 2079 | (10634, 75, 2), 2080 | (10635, 4, 10), 2081 | (10635, 5, 15), 2082 | (10635, 22, 40), 2083 | (10636, 4, 25), 2084 | (10636, 58, 6), 2085 | (10637, 11, 10), 2086 | (10637, 50, 25), 2087 | (10637, 56, 60), 2088 | (10638, 45, 20), 2089 | (10638, 65, 21), 2090 | (10638, 72, 60), 2091 | (10639, 18, 8), 2092 | (10640, 69, 20), 2093 | (10640, 70, 15), 2094 | (10641, 2, 50), 2095 | (10641, 40, 60), 2096 | (10642, 21, 30), 2097 | (10642, 61, 20), 2098 | (10643, 28, 15), 2099 | (10643, 39, 21), 2100 | (10643, 46, 2), 2101 | (10644, 18, 4), 2102 | (10644, 43, 20), 2103 | (10644, 46, 21), 2104 | (10645, 18, 20), 2105 | (10645, 36, 15), 2106 | (10646, 1, 15), 2107 | (10646, 10, 18), 2108 | (10646, 71, 30), 2109 | (10646, 77, 35), 2110 | (10647, 19, 30), 2111 | (10647, 39, 20), 2112 | (10648, 22, 15), 2113 | (10648, 24, 15), 2114 | (10649, 28, 20), 2115 | (10649, 72, 15), 2116 | (10650, 30, 30), 2117 | (10650, 53, 25), 2118 | (10650, 54, 30), 2119 | (10651, 19, 12), 2120 | (10651, 22, 20), 2121 | (10652, 30, 2), 2122 | (10652, 42, 20), 2123 | (10653, 16, 30), 2124 | (10653, 60, 20), 2125 | (10654, 4, 12), 2126 | (10654, 39, 20), 2127 | (10654, 54, 6), 2128 | (10655, 41, 20), 2129 | (10656, 14, 3), 2130 | (10656, 44, 28), 2131 | (10656, 47, 6), 2132 | (10657, 15, 50), 2133 | (10657, 41, 24), 2134 | (10657, 46, 45), 2135 | (10657, 47, 10), 2136 | (10657, 56, 45), 2137 | (10657, 60, 30), 2138 | (10658, 21, 60), 2139 | (10658, 40, 70), 2140 | (10658, 60, 55), 2141 | (10658, 77, 70), 2142 | (10659, 31, 20), 2143 | (10659, 40, 24), 2144 | (10659, 70, 40), 2145 | (10660, 20, 21), 2146 | (10661, 39, 3), 2147 | (10661, 58, 49), 2148 | (10662, 68, 10), 2149 | (10663, 40, 30), 2150 | (10663, 42, 30), 2151 | (10663, 51, 20), 2152 | (10664, 10, 24), 2153 | (10664, 56, 12), 2154 | (10664, 65, 15), 2155 | (10665, 51, 20), 2156 | (10665, 59, 1), 2157 | (10665, 76, 10), 2158 | (10666, 29, 36), 2159 | (10666, 65, 10), 2160 | (10667, 69, 45), 2161 | (10667, 71, 14), 2162 | (10668, 31, 8), 2163 | (10668, 55, 4), 2164 | (10668, 64, 15), 2165 | (10669, 36, 30), 2166 | (10670, 23, 32), 2167 | (10670, 46, 60), 2168 | (10670, 67, 25), 2169 | (10670, 73, 50), 2170 | (10670, 75, 25), 2171 | (10671, 16, 10), 2172 | (10671, 62, 10), 2173 | (10671, 65, 12), 2174 | (10672, 38, 15), 2175 | (10672, 71, 12), 2176 | (10673, 16, 3), 2177 | (10673, 42, 6), 2178 | (10673, 43, 6), 2179 | (10674, 23, 5), 2180 | (10675, 14, 30), 2181 | (10675, 53, 10), 2182 | (10675, 58, 30), 2183 | (10676, 10, 2), 2184 | (10676, 19, 7), 2185 | (10676, 44, 21), 2186 | (10677, 26, 30), 2187 | (10677, 33, 8), 2188 | (10678, 12, 100), 2189 | (10678, 33, 30), 2190 | (10678, 41, 120), 2191 | (10678, 54, 30), 2192 | (10679, 59, 12), 2193 | (10680, 16, 50), 2194 | (10680, 31, 20), 2195 | (10680, 42, 40), 2196 | (10681, 19, 30), 2197 | (10681, 21, 12), 2198 | (10681, 64, 28), 2199 | (10682, 33, 30), 2200 | (10682, 66, 4), 2201 | (10682, 75, 30), 2202 | (10683, 52, 9), 2203 | (10684, 40, 20), 2204 | (10684, 47, 40), 2205 | (10684, 60, 30), 2206 | (10685, 10, 20), 2207 | (10685, 41, 4), 2208 | (10685, 47, 15), 2209 | (10686, 17, 30), 2210 | (10686, 26, 15), 2211 | (10687, 9, 50), 2212 | (10687, 29, 10), 2213 | (10687, 36, 6), 2214 | (10688, 10, 18), 2215 | (10688, 28, 60), 2216 | (10688, 34, 14), 2217 | (10689, 1, 35), 2218 | (10690, 56, 20), 2219 | (10690, 77, 30), 2220 | (10691, 1, 30), 2221 | (10691, 29, 40), 2222 | (10691, 43, 40), 2223 | (10691, 44, 24), 2224 | (10691, 62, 48), 2225 | (10692, 63, 20), 2226 | (10693, 9, 6), 2227 | (10693, 54, 60), 2228 | (10693, 69, 30), 2229 | (10693, 73, 15), 2230 | (10694, 7, 90), 2231 | (10694, 59, 25), 2232 | (10694, 70, 50), 2233 | (10695, 8, 10), 2234 | (10695, 12, 4), 2235 | (10695, 24, 20), 2236 | (10696, 17, 20), 2237 | (10696, 46, 18), 2238 | (10697, 19, 7), 2239 | (10697, 35, 9), 2240 | (10697, 58, 30), 2241 | (10697, 70, 30), 2242 | (10698, 11, 15), 2243 | (10698, 17, 8), 2244 | (10698, 29, 12), 2245 | (10698, 65, 65), 2246 | (10698, 70, 8), 2247 | (10699, 47, 12), 2248 | (10700, 1, 5), 2249 | (10700, 34, 12), 2250 | (10700, 68, 40), 2251 | (10700, 71, 60), 2252 | (10701, 59, 42), 2253 | (10701, 71, 20), 2254 | (10701, 76, 35), 2255 | (10702, 3, 6), 2256 | (10702, 76, 15), 2257 | (10703, 2, 5), 2258 | (10703, 59, 35), 2259 | (10703, 73, 35), 2260 | (10704, 4, 6), 2261 | (10704, 24, 35), 2262 | (10704, 48, 24), 2263 | (10705, 31, 20), 2264 | (10705, 32, 4), 2265 | (10706, 16, 20), 2266 | (10706, 43, 24), 2267 | (10706, 59, 8), 2268 | (10707, 55, 21), 2269 | (10707, 57, 40), 2270 | (10707, 70, 28), 2271 | (10708, 5, 4), 2272 | (10708, 36, 5), 2273 | (10709, 8, 40), 2274 | (10709, 51, 28), 2275 | (10709, 60, 10), 2276 | (10710, 19, 5), 2277 | (10710, 47, 5), 2278 | (10711, 19, 12), 2279 | (10711, 41, 42), 2280 | (10711, 53, 120), 2281 | (10712, 53, 3), 2282 | (10712, 56, 30), 2283 | (10713, 10, 18), 2284 | (10713, 26, 30), 2285 | (10713, 45, 110), 2286 | (10713, 46, 24), 2287 | (10714, 2, 30), 2288 | (10714, 17, 27), 2289 | (10714, 47, 50), 2290 | (10714, 56, 18), 2291 | (10714, 58, 12), 2292 | (10715, 10, 21), 2293 | (10715, 71, 30), 2294 | (10716, 21, 5), 2295 | (10716, 51, 7), 2296 | (10716, 61, 10), 2297 | (10717, 21, 32), 2298 | (10717, 54, 15), 2299 | (10717, 69, 25), 2300 | (10718, 12, 36), 2301 | (10718, 16, 20), 2302 | (10718, 36, 40), 2303 | (10718, 62, 20), 2304 | (10719, 18, 12), 2305 | (10719, 30, 3), 2306 | (10719, 54, 40), 2307 | (10720, 35, 21), 2308 | (10720, 71, 8), 2309 | (10721, 44, 50), 2310 | (10722, 2, 3), 2311 | (10722, 31, 50), 2312 | (10722, 68, 45), 2313 | (10722, 75, 42), 2314 | (10723, 26, 15), 2315 | (10724, 10, 16), 2316 | (10724, 61, 5), 2317 | (10725, 41, 12), 2318 | (10725, 52, 4), 2319 | (10725, 55, 6), 2320 | (10726, 4, 25), 2321 | (10726, 11, 5), 2322 | (10727, 17, 20), 2323 | (10727, 56, 10), 2324 | (10727, 59, 10), 2325 | (10728, 30, 15), 2326 | (10728, 40, 6), 2327 | (10728, 55, 12), 2328 | (10728, 60, 15), 2329 | (10729, 1, 50), 2330 | (10729, 21, 30), 2331 | (10729, 50, 40), 2332 | (10730, 16, 15), 2333 | (10730, 31, 3), 2334 | (10730, 65, 10), 2335 | (10731, 21, 40), 2336 | (10731, 51, 30), 2337 | (10732, 76, 20), 2338 | (10733, 14, 16), 2339 | (10733, 28, 20), 2340 | (10733, 52, 25), 2341 | (10734, 6, 30), 2342 | (10734, 30, 15), 2343 | (10734, 76, 20), 2344 | (10735, 61, 20), 2345 | (10735, 77, 2), 2346 | (10736, 65, 40), 2347 | (10736, 75, 20), 2348 | (10737, 13, 4), 2349 | (10737, 41, 12), 2350 | (10738, 16, 3), 2351 | (10739, 36, 6), 2352 | (10739, 52, 18), 2353 | (10740, 28, 5), 2354 | (10740, 35, 35), 2355 | (10740, 45, 40), 2356 | (10740, 56, 14), 2357 | (10741, 2, 15), 2358 | (10742, 3, 20), 2359 | (10742, 60, 50), 2360 | (10742, 72, 35), 2361 | (10743, 46, 28), 2362 | (10744, 40, 50), 2363 | (10745, 18, 24), 2364 | (10745, 44, 16), 2365 | (10745, 59, 45), 2366 | (10745, 72, 7), 2367 | (10746, 13, 6), 2368 | (10746, 42, 28), 2369 | (10746, 62, 9), 2370 | (10746, 69, 40), 2371 | (10747, 31, 8), 2372 | (10747, 41, 35), 2373 | (10747, 63, 9), 2374 | (10747, 69, 30), 2375 | (10748, 23, 44), 2376 | (10748, 40, 40), 2377 | (10748, 56, 28), 2378 | (10749, 56, 15), 2379 | (10749, 59, 6), 2380 | (10749, 76, 10), 2381 | (10750, 14, 5), 2382 | (10750, 45, 40), 2383 | (10750, 59, 25), 2384 | (10751, 26, 12), 2385 | (10751, 30, 30), 2386 | (10751, 50, 20), 2387 | (10751, 73, 15), 2388 | (10752, 1, 8), 2389 | (10752, 69, 3), 2390 | (10753, 45, 4), 2391 | (10753, 74, 5), 2392 | (10754, 40, 3), 2393 | (10755, 47, 30), 2394 | (10755, 56, 30), 2395 | (10755, 57, 14), 2396 | (10755, 69, 25), 2397 | (10756, 18, 21), 2398 | (10756, 36, 20), 2399 | (10756, 68, 6), 2400 | (10756, 69, 20), 2401 | (10757, 34, 30), 2402 | (10757, 59, 7), 2403 | (10757, 62, 30), 2404 | (10757, 64, 24), 2405 | (10758, 26, 20), 2406 | (10758, 52, 60), 2407 | (10758, 70, 40), 2408 | (10759, 32, 10), 2409 | (10760, 25, 12), 2410 | (10760, 27, 40), 2411 | (10760, 43, 30), 2412 | (10761, 25, 35), 2413 | (10761, 75, 18), 2414 | (10762, 39, 16), 2415 | (10762, 47, 30), 2416 | (10762, 51, 28), 2417 | (10762, 56, 60), 2418 | (10763, 21, 40), 2419 | (10763, 22, 6), 2420 | (10763, 24, 20), 2421 | (10764, 3, 20), 2422 | (10764, 39, 130), 2423 | (10765, 65, 80), 2424 | (10766, 2, 40), 2425 | (10766, 7, 35), 2426 | (10766, 68, 40), 2427 | (10767, 42, 2), 2428 | (10768, 22, 4), 2429 | (10768, 31, 50), 2430 | (10768, 60, 15), 2431 | (10768, 71, 12), 2432 | (10769, 41, 30), 2433 | (10769, 52, 15), 2434 | (10769, 61, 20), 2435 | (10769, 62, 15), 2436 | (10770, 11, 15), 2437 | (10771, 71, 16), 2438 | (10772, 29, 18), 2439 | (10772, 59, 25), 2440 | (10773, 17, 33), 2441 | (10773, 31, 70), 2442 | (10773, 75, 7), 2443 | (10774, 31, 2), 2444 | (10774, 66, 50), 2445 | (10775, 10, 6), 2446 | (10775, 67, 3), 2447 | (10776, 31, 16), 2448 | (10776, 42, 12), 2449 | (10776, 45, 27), 2450 | (10776, 51, 120), 2451 | (10777, 42, 20), 2452 | (10778, 41, 10), 2453 | (10779, 16, 20), 2454 | (10779, 62, 20), 2455 | (10780, 70, 35), 2456 | (10780, 77, 15), 2457 | (10781, 54, 3), 2458 | (10781, 56, 20), 2459 | (10781, 74, 35), 2460 | (10782, 31, 1), 2461 | (10783, 31, 10), 2462 | (10783, 38, 5), 2463 | (10784, 36, 30), 2464 | (10784, 39, 2), 2465 | (10784, 72, 30), 2466 | (10785, 10, 10), 2467 | (10785, 75, 10), 2468 | (10786, 8, 30), 2469 | (10786, 30, 15), 2470 | (10786, 75, 42), 2471 | (10787, 2, 15), 2472 | (10787, 29, 20), 2473 | (10788, 19, 50), 2474 | (10788, 75, 40), 2475 | (10789, 18, 30), 2476 | (10789, 35, 15), 2477 | (10789, 63, 30), 2478 | (10789, 68, 18), 2479 | (10790, 7, 3), 2480 | (10790, 56, 20), 2481 | (10791, 29, 14), 2482 | (10791, 41, 20), 2483 | (10792, 2, 10), 2484 | (10792, 54, 3), 2485 | (10792, 68, 15), 2486 | (10793, 41, 14), 2487 | (10793, 52, 8), 2488 | (10794, 14, 15), 2489 | (10794, 54, 6), 2490 | (10795, 16, 65), 2491 | (10795, 17, 35), 2492 | (10796, 26, 21), 2493 | (10796, 44, 10), 2494 | (10796, 64, 35), 2495 | (10796, 69, 24), 2496 | (10797, 11, 20), 2497 | (10798, 62, 2), 2498 | (10798, 72, 10), 2499 | (10799, 13, 20), 2500 | (10799, 24, 20), 2501 | (10799, 59, 25), 2502 | (10800, 11, 50), 2503 | (10800, 51, 10), 2504 | (10800, 54, 7), 2505 | (10801, 17, 40), 2506 | (10801, 29, 20), 2507 | (10802, 30, 25), 2508 | (10802, 51, 30), 2509 | (10802, 55, 60), 2510 | (10802, 62, 5), 2511 | (10803, 19, 24), 2512 | (10803, 25, 15), 2513 | (10803, 59, 15), 2514 | (10804, 10, 36), 2515 | (10804, 28, 24), 2516 | (10804, 49, 4), 2517 | (10805, 34, 10), 2518 | (10805, 38, 10), 2519 | (10806, 2, 20), 2520 | (10806, 65, 2), 2521 | (10806, 74, 15), 2522 | (10807, 40, 1), 2523 | (10808, 56, 20), 2524 | (10808, 76, 50), 2525 | (10809, 52, 20), 2526 | (10810, 13, 7), 2527 | (10810, 25, 5), 2528 | (10810, 70, 5), 2529 | (10811, 19, 15), 2530 | (10811, 23, 18), 2531 | (10811, 40, 30), 2532 | (10812, 31, 16), 2533 | (10812, 72, 40), 2534 | (10812, 77, 20), 2535 | (10813, 2, 12), 2536 | (10813, 46, 35), 2537 | (10814, 41, 20), 2538 | (10814, 43, 20), 2539 | (10814, 48, 8), 2540 | (10814, 61, 30), 2541 | (10815, 33, 16), 2542 | (10816, 38, 30), 2543 | (10816, 62, 20), 2544 | (10817, 26, 40), 2545 | (10817, 38, 30), 2546 | (10817, 40, 60), 2547 | (10817, 62, 25), 2548 | (10818, 32, 20), 2549 | (10818, 41, 20), 2550 | (10819, 43, 7), 2551 | (10819, 75, 20), 2552 | (10820, 56, 30), 2553 | (10821, 35, 20), 2554 | (10821, 51, 6), 2555 | (10822, 62, 3), 2556 | (10822, 70, 6), 2557 | (10823, 11, 20), 2558 | (10823, 57, 15), 2559 | (10823, 59, 40), 2560 | (10823, 77, 15), 2561 | (10824, 41, 12), 2562 | (10824, 70, 9), 2563 | (10825, 26, 12), 2564 | (10825, 53, 20), 2565 | (10826, 31, 35), 2566 | (10826, 57, 15), 2567 | (10827, 10, 15), 2568 | (10827, 39, 21), 2569 | (10828, 20, 5), 2570 | (10828, 38, 2), 2571 | (10829, 2, 10), 2572 | (10829, 8, 20), 2573 | (10829, 13, 10), 2574 | (10829, 60, 21), 2575 | (10830, 6, 6), 2576 | (10830, 39, 28), 2577 | (10830, 60, 30), 2578 | (10830, 68, 24), 2579 | (10831, 19, 2), 2580 | (10831, 35, 8), 2581 | (10831, 38, 8), 2582 | (10831, 43, 9), 2583 | (10832, 13, 3), 2584 | (10832, 25, 10), 2585 | (10832, 44, 16), 2586 | (10832, 64, 3), 2587 | (10833, 7, 20), 2588 | (10833, 31, 9), 2589 | (10833, 53, 9), 2590 | (10834, 29, 8), 2591 | (10834, 30, 20), 2592 | (10835, 59, 15), 2593 | (10835, 77, 2), 2594 | (10836, 22, 52), 2595 | (10836, 35, 6), 2596 | (10836, 57, 24), 2597 | (10836, 60, 60), 2598 | (10836, 64, 30), 2599 | (10837, 13, 6), 2600 | (10837, 40, 25), 2601 | (10837, 47, 40), 2602 | (10837, 76, 21), 2603 | (10838, 1, 4), 2604 | (10838, 18, 25), 2605 | (10838, 36, 50), 2606 | (10839, 58, 30), 2607 | (10839, 72, 15), 2608 | (10840, 25, 6), 2609 | (10840, 39, 10), 2610 | (10841, 10, 16), 2611 | (10841, 56, 30), 2612 | (10841, 59, 50), 2613 | (10841, 77, 15), 2614 | (10842, 11, 15), 2615 | (10842, 43, 5), 2616 | (10842, 68, 20), 2617 | (10842, 70, 12), 2618 | (10843, 51, 4), 2619 | (10844, 22, 35), 2620 | (10845, 23, 70), 2621 | (10845, 35, 25), 2622 | (10845, 42, 42), 2623 | (10845, 58, 60), 2624 | (10845, 64, 48), 2625 | (10846, 4, 21), 2626 | (10846, 70, 30), 2627 | (10846, 74, 20), 2628 | (10847, 1, 80), 2629 | (10847, 19, 12), 2630 | (10847, 37, 60), 2631 | (10847, 45, 36), 2632 | (10847, 60, 45), 2633 | (10847, 71, 55), 2634 | (10848, 5, 30), 2635 | (10848, 9, 3), 2636 | (10849, 3, 49), 2637 | (10849, 26, 18), 2638 | (10850, 25, 20), 2639 | (10850, 33, 4), 2640 | (10850, 70, 30), 2641 | (10851, 2, 5), 2642 | (10851, 25, 10), 2643 | (10851, 57, 10), 2644 | (10851, 59, 42), 2645 | (10852, 2, 15), 2646 | (10852, 17, 6), 2647 | (10852, 62, 50), 2648 | (10853, 18, 10), 2649 | (10854, 10, 100), 2650 | (10854, 13, 65), 2651 | (10855, 16, 50), 2652 | (10855, 31, 14), 2653 | (10855, 56, 24), 2654 | (10855, 65, 15), 2655 | (10856, 2, 20), 2656 | (10856, 42, 20), 2657 | (10857, 3, 30), 2658 | (10857, 26, 35), 2659 | (10857, 29, 10), 2660 | (10858, 7, 5), 2661 | (10858, 27, 10), 2662 | (10858, 70, 4), 2663 | (10859, 24, 40), 2664 | (10859, 54, 35), 2665 | (10859, 64, 30), 2666 | (10860, 51, 3), 2667 | (10860, 76, 20), 2668 | (10861, 17, 42), 2669 | (10861, 18, 20), 2670 | (10861, 21, 40), 2671 | (10861, 33, 35), 2672 | (10861, 62, 3), 2673 | (10862, 11, 25), 2674 | (10862, 52, 8), 2675 | (10863, 1, 20), 2676 | (10863, 58, 12), 2677 | (10864, 35, 4), 2678 | (10864, 67, 15), 2679 | (10865, 38, 60), 2680 | (10865, 39, 80), 2681 | (10866, 2, 21), 2682 | (10866, 24, 6), 2683 | (10866, 30, 40), 2684 | (10867, 53, 3), 2685 | (10868, 26, 20), 2686 | (10868, 35, 30), 2687 | (10868, 49, 42), 2688 | (10869, 1, 40), 2689 | (10869, 11, 10), 2690 | (10869, 23, 50), 2691 | (10869, 68, 20), 2692 | (10870, 35, 3), 2693 | (10870, 51, 2), 2694 | (10871, 6, 50), 2695 | (10871, 16, 12), 2696 | (10871, 17, 16), 2697 | (10872, 55, 10), 2698 | (10872, 62, 20), 2699 | (10872, 64, 15), 2700 | (10872, 65, 21), 2701 | (10873, 21, 20), 2702 | (10873, 28, 3), 2703 | (10874, 10, 10), 2704 | (10875, 19, 25), 2705 | (10875, 47, 21), 2706 | (10875, 49, 15), 2707 | (10876, 46, 21), 2708 | (10876, 64, 20), 2709 | (10877, 16, 30), 2710 | (10877, 18, 25), 2711 | (10878, 20, 20), 2712 | (10879, 40, 12), 2713 | (10879, 65, 10), 2714 | (10879, 76, 10), 2715 | (10880, 23, 30), 2716 | (10880, 61, 30), 2717 | (10880, 70, 50), 2718 | (10881, 73, 10), 2719 | (10882, 42, 25), 2720 | (10882, 49, 20), 2721 | (10882, 54, 32), 2722 | (10883, 24, 8), 2723 | (10884, 21, 40), 2724 | (10884, 56, 21), 2725 | (10884, 65, 12), 2726 | (10885, 2, 20), 2727 | (10885, 24, 12), 2728 | (10885, 70, 30), 2729 | (10885, 77, 25), 2730 | (10886, 10, 70), 2731 | (10886, 31, 35), 2732 | (10886, 77, 40), 2733 | (10887, 25, 5), 2734 | (10888, 2, 20), 2735 | (10888, 68, 18), 2736 | (10889, 11, 40), 2737 | (10889, 38, 40), 2738 | (10890, 17, 15), 2739 | (10890, 34, 10), 2740 | (10890, 41, 14), 2741 | (10891, 30, 15), 2742 | (10892, 59, 40), 2743 | (10893, 8, 30), 2744 | (10893, 24, 10), 2745 | (10893, 29, 24), 2746 | (10893, 30, 35), 2747 | (10893, 36, 20), 2748 | (10894, 13, 28), 2749 | (10894, 69, 50), 2750 | (10894, 75, 120), 2751 | (10895, 24, 110), 2752 | (10895, 39, 45), 2753 | (10895, 40, 91), 2754 | (10895, 60, 100), 2755 | (10896, 45, 15), 2756 | (10896, 56, 16), 2757 | (10897, 29, 80), 2758 | (10897, 30, 36), 2759 | (10898, 13, 5), 2760 | (10899, 39, 8), 2761 | (10900, 70, 3), 2762 | (10901, 41, 30), 2763 | (10901, 71, 30), 2764 | (10902, 55, 30), 2765 | (10902, 62, 6), 2766 | (10903, 13, 40), 2767 | (10903, 65, 21), 2768 | (10903, 68, 20), 2769 | (10904, 58, 15), 2770 | (10904, 62, 35), 2771 | (10905, 1, 20), 2772 | (10906, 61, 15), 2773 | (10907, 75, 14), 2774 | (10908, 7, 20), 2775 | (10908, 52, 14), 2776 | (10909, 7, 12), 2777 | (10909, 16, 15), 2778 | (10909, 41, 5), 2779 | (10910, 19, 12), 2780 | (10910, 49, 10), 2781 | (10910, 61, 5), 2782 | (10911, 1, 10), 2783 | (10911, 17, 12), 2784 | (10911, 67, 15), 2785 | (10912, 11, 40), 2786 | (10912, 29, 60), 2787 | (10913, 4, 30), 2788 | (10913, 33, 40), 2789 | (10913, 58, 15), 2790 | (10914, 71, 25), 2791 | (10915, 17, 10), 2792 | (10915, 33, 30), 2793 | (10915, 54, 10), 2794 | (10916, 16, 6), 2795 | (10916, 32, 6), 2796 | (10916, 57, 20), 2797 | (10917, 30, 1), 2798 | (10917, 60, 10), 2799 | (10918, 1, 60), 2800 | (10918, 60, 25), 2801 | (10919, 16, 24), 2802 | (10919, 25, 24), 2803 | (10919, 40, 20), 2804 | (10920, 50, 24), 2805 | (10921, 35, 10), 2806 | (10921, 63, 40), 2807 | (10922, 17, 15), 2808 | (10922, 24, 35), 2809 | (10923, 42, 10), 2810 | (10923, 43, 10), 2811 | (10923, 67, 24), 2812 | (10924, 10, 20), 2813 | (10924, 28, 30), 2814 | (10924, 75, 6), 2815 | (10925, 36, 25), 2816 | (10925, 52, 12), 2817 | (10926, 11, 2), 2818 | (10926, 13, 10), 2819 | (10926, 19, 7), 2820 | (10926, 72, 10), 2821 | (10927, 20, 5), 2822 | (10927, 52, 5), 2823 | (10927, 76, 20), 2824 | (10928, 47, 5), 2825 | (10928, 76, 5), 2826 | (10929, 21, 60), 2827 | (10929, 75, 49), 2828 | (10929, 77, 15), 2829 | (10930, 21, 36), 2830 | (10930, 27, 25), 2831 | (10930, 55, 25), 2832 | (10930, 58, 30), 2833 | (10931, 13, 42), 2834 | (10931, 57, 30), 2835 | (10932, 16, 30), 2836 | (10932, 62, 14), 2837 | (10932, 72, 16), 2838 | (10932, 75, 20), 2839 | (10933, 53, 2), 2840 | (10933, 61, 30), 2841 | (10934, 6, 20), 2842 | (10935, 1, 21), 2843 | (10935, 18, 4), 2844 | (10935, 23, 8), 2845 | (10936, 36, 30), 2846 | (10937, 28, 8), 2847 | (10937, 34, 20), 2848 | (10938, 13, 20), 2849 | (10938, 43, 24), 2850 | (10938, 60, 49), 2851 | (10938, 71, 35), 2852 | (10939, 2, 10), 2853 | (10939, 67, 40), 2854 | (10940, 7, 8), 2855 | (10940, 13, 20), 2856 | (10941, 31, 44), 2857 | (10941, 62, 30), 2858 | (10941, 68, 80), 2859 | (10941, 72, 50), 2860 | (10942, 49, 28), 2861 | (10943, 13, 15), 2862 | (10943, 22, 21), 2863 | (10943, 46, 15), 2864 | (10944, 11, 5), 2865 | (10944, 44, 18), 2866 | (10944, 56, 18), 2867 | (10945, 13, 20), 2868 | (10945, 31, 10), 2869 | (10946, 10, 25), 2870 | (10946, 24, 25), 2871 | (10946, 77, 40), 2872 | (10947, 59, 4), 2873 | (10948, 50, 9), 2874 | (10948, 51, 40), 2875 | (10948, 55, 4), 2876 | (10949, 6, 12), 2877 | (10949, 10, 30), 2878 | (10949, 17, 6), 2879 | (10949, 62, 60), 2880 | (10950, 4, 5), 2881 | (10951, 33, 15), 2882 | (10951, 41, 6), 2883 | (10951, 75, 50), 2884 | (10952, 6, 16), 2885 | (10952, 28, 2), 2886 | (10953, 20, 50), 2887 | (10953, 31, 50), 2888 | (10954, 16, 28), 2889 | (10954, 31, 25), 2890 | (10954, 45, 30), 2891 | (10954, 60, 24), 2892 | (10955, 75, 12), 2893 | (10956, 21, 12), 2894 | (10956, 47, 14), 2895 | (10956, 51, 8), 2896 | (10957, 30, 30), 2897 | (10957, 35, 40), 2898 | (10957, 64, 8), 2899 | (10958, 5, 20), 2900 | (10958, 7, 6), 2901 | (10958, 72, 5), 2902 | (10959, 75, 20), 2903 | (10960, 24, 10), 2904 | (10960, 41, 24), 2905 | (10961, 52, 6), 2906 | (10961, 76, 60), 2907 | (10962, 7, 45), 2908 | (10962, 13, 77), 2909 | (10962, 53, 20), 2910 | (10962, 69, 9), 2911 | (10962, 76, 44), 2912 | (10963, 60, 2), 2913 | (10964, 18, 6), 2914 | (10964, 38, 5), 2915 | (10964, 69, 10), 2916 | (10965, 51, 16), 2917 | (10966, 37, 8), 2918 | (10966, 56, 12), 2919 | (10966, 62, 12), 2920 | (10967, 19, 12), 2921 | (10967, 49, 40), 2922 | (10968, 12, 30), 2923 | (10968, 24, 30), 2924 | (10968, 64, 4), 2925 | (10969, 46, 9), 2926 | (10970, 52, 40), 2927 | (10971, 29, 14), 2928 | (10972, 17, 6), 2929 | (10972, 33, 7), 2930 | (10973, 26, 5), 2931 | (10973, 41, 6), 2932 | (10973, 75, 10), 2933 | (10974, 63, 10), 2934 | (10975, 8, 16), 2935 | (10975, 75, 10), 2936 | (10976, 28, 20), 2937 | (10977, 39, 30), 2938 | (10977, 47, 30), 2939 | (10977, 51, 10), 2940 | (10977, 63, 20), 2941 | (10978, 8, 20), 2942 | (10978, 21, 40), 2943 | (10978, 40, 10), 2944 | (10978, 44, 6), 2945 | (10979, 7, 18), 2946 | (10979, 12, 20), 2947 | (10979, 24, 80), 2948 | (10979, 27, 30), 2949 | (10979, 31, 24), 2950 | (10979, 63, 35), 2951 | (10980, 75, 40), 2952 | (10981, 38, 60), 2953 | (10982, 7, 20), 2954 | (10982, 43, 9), 2955 | (10983, 13, 84), 2956 | (10983, 57, 15), 2957 | (10984, 16, 55), 2958 | (10984, 24, 20), 2959 | (10984, 36, 40), 2960 | (10985, 16, 36), 2961 | (10985, 18, 8), 2962 | (10985, 32, 35), 2963 | (10986, 11, 30), 2964 | (10986, 20, 15), 2965 | (10986, 76, 10), 2966 | (10986, 77, 15), 2967 | (10987, 7, 60), 2968 | (10987, 43, 6), 2969 | (10987, 72, 20), 2970 | (10988, 7, 60), 2971 | (10988, 62, 40), 2972 | (10989, 6, 40), 2973 | (10989, 11, 15), 2974 | (10989, 41, 4), 2975 | (10990, 21, 65), 2976 | (10990, 34, 60), 2977 | (10990, 55, 65), 2978 | (10990, 61, 66), 2979 | (10991, 2, 50), 2980 | (10991, 70, 20), 2981 | (10991, 76, 90), 2982 | (10992, 72, 2), 2983 | (10993, 29, 50), 2984 | (10993, 41, 35), 2985 | (10994, 59, 18), 2986 | (10995, 51, 20), 2987 | (10995, 60, 4), 2988 | (10996, 42, 40), 2989 | (10997, 32, 50), 2990 | (10997, 46, 20), 2991 | (10997, 52, 20), 2992 | (10998, 24, 12), 2993 | (10998, 61, 7), 2994 | (10998, 74, 20), 2995 | (10998, 75, 30), 2996 | (10999, 41, 20), 2997 | (10999, 51, 15), 2998 | (10999, 77, 21), 2999 | (11000, 4, 25), 3000 | (11000, 24, 30), 3001 | (11000, 77, 30), 3002 | (11001, 7, 60), 3003 | (11001, 22, 25), 3004 | (11001, 46, 25), 3005 | (11001, 55, 6), 3006 | (11002, 13, 56), 3007 | (11002, 35, 15), 3008 | (11002, 42, 24), 3009 | (11002, 55, 40), 3010 | (11003, 1, 4), 3011 | (11003, 40, 10), 3012 | (11003, 52, 10), 3013 | (11004, 26, 6), 3014 | (11004, 76, 6), 3015 | (11005, 1, 2), 3016 | (11005, 59, 10), 3017 | (11006, 1, 8), 3018 | (11006, 29, 2), 3019 | (11007, 8, 30), 3020 | (11007, 29, 10), 3021 | (11007, 42, 14), 3022 | (11008, 28, 70), 3023 | (11008, 34, 90), 3024 | (11008, 71, 21), 3025 | (11009, 24, 12), 3026 | (11009, 36, 18), 3027 | (11009, 60, 9), 3028 | (11010, 7, 20), 3029 | (11010, 24, 10), 3030 | (11011, 58, 40), 3031 | (11011, 71, 20), 3032 | (11012, 19, 50), 3033 | (11012, 60, 36), 3034 | (11012, 71, 60), 3035 | (11013, 23, 10), 3036 | (11013, 42, 4), 3037 | (11013, 45, 20), 3038 | (11013, 68, 2), 3039 | (11014, 41, 28), 3040 | (11015, 30, 15), 3041 | (11015, 77, 18), 3042 | (11016, 31, 15), 3043 | (11016, 36, 16), 3044 | (11017, 3, 25), 3045 | (11017, 59, 110), 3046 | (11017, 70, 30), 3047 | (11018, 12, 20), 3048 | (11018, 18, 10), 3049 | (11018, 56, 5), 3050 | (11019, 46, 3), 3051 | (11019, 49, 2), 3052 | (11020, 10, 24), 3053 | (11021, 2, 11), 3054 | (11021, 20, 15), 3055 | (11021, 26, 63), 3056 | (11021, 51, 44), 3057 | (11021, 72, 35), 3058 | (11022, 19, 35), 3059 | (11022, 69, 30), 3060 | (11023, 7, 4), 3061 | (11023, 43, 30), 3062 | (11024, 26, 12), 3063 | (11024, 33, 30), 3064 | (11024, 65, 21), 3065 | (11024, 71, 50), 3066 | (11025, 1, 10), 3067 | (11025, 13, 20), 3068 | (11026, 18, 8), 3069 | (11026, 51, 10), 3070 | (11027, 24, 30), 3071 | (11027, 62, 21), 3072 | (11028, 55, 35), 3073 | (11028, 59, 24), 3074 | (11029, 56, 20), 3075 | (11029, 63, 12), 3076 | (11030, 2, 100), 3077 | (11030, 5, 70), 3078 | (11030, 29, 60), 3079 | (11030, 59, 100), 3080 | (11031, 1, 45), 3081 | (11031, 13, 80), 3082 | (11031, 24, 21), 3083 | (11031, 64, 20), 3084 | (11031, 71, 16), 3085 | (11032, 36, 35), 3086 | (11032, 38, 25), 3087 | (11032, 59, 30), 3088 | (11033, 53, 70), 3089 | (11033, 69, 36), 3090 | (11034, 21, 15), 3091 | (11034, 44, 12), 3092 | (11034, 61, 6), 3093 | (11035, 1, 10), 3094 | (11035, 35, 60), 3095 | (11035, 42, 30), 3096 | (11035, 54, 10), 3097 | (11036, 13, 7), 3098 | (11036, 59, 30), 3099 | (11037, 70, 4), 3100 | (11038, 40, 5), 3101 | (11038, 52, 2), 3102 | (11038, 71, 30), 3103 | (11039, 28, 20), 3104 | (11039, 35, 24), 3105 | (11039, 49, 60), 3106 | (11039, 57, 28), 3107 | (11040, 21, 20), 3108 | (11041, 2, 30), 3109 | (11041, 63, 30), 3110 | (11042, 44, 15), 3111 | (11042, 61, 4), 3112 | (11043, 11, 10), 3113 | (11044, 62, 12), 3114 | (11045, 33, 15), 3115 | (11045, 51, 24), 3116 | (11046, 12, 20), 3117 | (11046, 32, 15), 3118 | (11046, 35, 18), 3119 | (11047, 1, 25), 3120 | (11047, 5, 30), 3121 | (11048, 68, 42), 3122 | (11049, 2, 10), 3123 | (11049, 12, 4), 3124 | (11050, 76, 50), 3125 | (11051, 24, 10), 3126 | (11052, 43, 30), 3127 | (11052, 61, 10), 3128 | (11053, 18, 35), 3129 | (11053, 32, 20), 3130 | (11053, 64, 25), 3131 | (11054, 33, 10), 3132 | (11054, 67, 20), 3133 | (11055, 24, 15), 3134 | (11055, 25, 15), 3135 | (11055, 51, 20), 3136 | (11055, 57, 20), 3137 | (11056, 7, 40), 3138 | (11056, 55, 35), 3139 | (11056, 60, 50), 3140 | (11057, 70, 3), 3141 | (11058, 21, 3), 3142 | (11058, 60, 21), 3143 | (11058, 61, 4), 3144 | (11059, 13, 30), 3145 | (11059, 17, 12), 3146 | (11059, 60, 35), 3147 | (11060, 60, 4), 3148 | (11060, 77, 10), 3149 | (11061, 60, 15), 3150 | (11062, 53, 10), 3151 | (11062, 70, 12), 3152 | (11063, 34, 30), 3153 | (11063, 40, 40), 3154 | (11063, 41, 30), 3155 | (11064, 17, 77), 3156 | (11064, 41, 12), 3157 | (11064, 53, 25), 3158 | (11064, 55, 4), 3159 | (11064, 68, 55), 3160 | (11065, 30, 4), 3161 | (11065, 54, 20), 3162 | (11066, 16, 3), 3163 | (11066, 19, 42), 3164 | (11066, 34, 35), 3165 | (11067, 41, 9), 3166 | (11068, 28, 8), 3167 | (11068, 43, 36), 3168 | (11068, 77, 28), 3169 | (11069, 39, 20), 3170 | (11070, 1, 40), 3171 | (11070, 2, 20), 3172 | (11070, 16, 30), 3173 | (11070, 31, 20), 3174 | (11071, 7, 15), 3175 | (11071, 13, 10), 3176 | (11072, 2, 8), 3177 | (11072, 41, 40), 3178 | (11072, 50, 22), 3179 | (11072, 64, 130), 3180 | (11073, 11, 10), 3181 | (11073, 24, 20), 3182 | (11074, 16, 14), 3183 | (11075, 2, 10), 3184 | (11075, 46, 30), 3185 | (11075, 76, 2), 3186 | (11076, 6, 20), 3187 | (11076, 14, 20), 3188 | (11076, 19, 10), 3189 | (11077, 2, 24), 3190 | (11077, 3, 4), 3191 | (11077, 4, 1), 3192 | (11077, 6, 1), 3193 | (11077, 7, 1), 3194 | (11077, 8, 2), 3195 | (11077, 10, 1), 3196 | (11077, 12, 2), 3197 | (11077, 13, 4), 3198 | (11077, 14, 1), 3199 | (11077, 16, 2), 3200 | (11077, 20, 1), 3201 | (11077, 23, 2), 3202 | (11077, 32, 1), 3203 | (11077, 39, 2), 3204 | (11077, 41, 3), 3205 | (11077, 46, 3), 3206 | (11077, 52, 2), 3207 | (11077, 55, 2), 3208 | (11077, 60, 2), 3209 | (11077, 64, 2), 3210 | (11077, 66, 1), 3211 | (11077, 73, 2), 3212 | (11077, 75, 4), 3213 | (11077, 77, 2); 3214 | 3215 | CREATE TABLE testproducts ( 3216 | testproduct_id SERIAL NOT NULL PRIMARY KEY, 3217 | product_name text, 3218 | category_id INT 3219 | ); 3220 | 3221 | INSERT INTO testproducts (product_name, category_id) 3222 | VALUES 3223 | ('Johns Fruit Cake', 3), 3224 | ('Marys Healthy Mix', 9), 3225 | ('Peters Scary Stuff', 10), 3226 | ('Jims Secret Recipe', 11), 3227 | ('Elisabeths Best Apples', 12), 3228 | ('Janes Favorite Cheese', 4), 3229 | ('Billys Home Made Pizza', 13), 3230 | ('Ellas Special Salmon', 8), 3231 | ('Roberts Rich Spaghetti', 5), 3232 | ('Mias Popular Ice', 14); 3233 | -------------------------------------------------------------------------------- /Window functions TODO.md: -------------------------------------------------------------------------------- 1 | ## Window functions TODO 2 | > [!IMPORTANT] 3 | > Before you proceed, read the reference [here](https://www.postgresql.org/docs/current/tutorial-window.html#TUTORIAL-WINDOW). 4 | > Pay special attention to window frame definition [here](https://www.postgresql.org/docs/current/sql-expressions.html#SYNTAX-WINDOW-FUNCTIONS) 5 | > and important built-in functions [here](https://www.postgresql.org/docs/current/functions-window.html#FUNCTIONS-WINDOW). 6 | > 7 | > You may also have a look at `generate_series` [here](https://www.postgresql.org/docs/current/functions-srf.html#FUNCTIONS-SRF) 8 | 9 | There are 3 tables, DDL below 10 | ```sql 11 | create table person 12 | ( 13 | id serial primary key not null, 14 | name text not null, 15 | details jsonb not null default '{}' 16 | ); 17 | -- JSON column "details" is a mimic or several properties 18 | -- and not necessarily an example of proper data design 19 | 20 | create table initial_ballance 21 | ( 22 | id serial primary key not null, 23 | person_id integer not null references person(id), 24 | ballance_date date not null default '2020-01-01', 25 | ballance numeric, 26 | misc jsonb not null default '{}' 27 | ); 28 | -- JSON column "misc" is a mimic or possible optional properties 29 | -- and not necessarily an example of proper data design 30 | 31 | create table transaction 32 | ( 33 | id serial primary key not null, 34 | person_id integer not null references person(id), 35 | transaction_date date not null, 36 | value numeric, -- negative for money spent 37 | misc jsonb not null default '{}' 38 | ); 39 | -- JSON column "misc" is a mimic or possible optional properties 40 | -- and not necessarily an example of proper data design 41 | 42 | -- Populate the tables 43 | 44 | insert into person (name) values ('Георги'), ('Петър'), ('Мария'); 45 | insert into initial_ballance (person_id, ballance) values (1, 100), (2, 150), (3, 200); 46 | 47 | insert into transaction (person_id, transaction_date, value) 48 | with t as (select generate_series(1, 100, 1)), -- just 100 rows 49 | p as (select id as pid from person) -- list of person id-s 50 | select 51 | pid, 52 | '2020-01-01'::date + (random() * (current_date - '2020-01-01'))::integer, 53 | (random() * 100 - 50)::numeric(10, 2) 54 | from t cross join p; -- all persons for each row of CTE t 55 | ``` 56 | ![image](https://github.com/user-attachments/assets/ed2be3c8-8af4-432d-95ab-084f2b9824c4) 57 | 58 | ## To do 59 | #### A simplified - yet realistic - bank account statement 60 | - What is the ballance per person now? (a result per person) 61 | - What has the ballance been for every person after every transaction of his? (a result per transaction, may filter by `person_id`) 62 | - an extra requirement with a smile - _present_ the integer part of transaction values in a separate column as roman numerals (ex. `47.39` becomes `XLVII`, `-19` becomes `sine XIX`) 63 | -------------------------------------------------------------------------------- /You may also like/readme.md: -------------------------------------------------------------------------------- 1 | A discussion on [PostgreSQL patterns](https://mccue.dev/pages/3-11-25-life-altering-postgresql-patterns) 2 | Postgres & Oracle [together](https://www.cybertec-postgresql.com/en/swiss-database-synergy-day-2025/) 3 | -------------------------------------------------------------------------------- /join/Cooking ERD.png: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/stefanov-sm/Database-XI/3d4c68199bb9cf0bee3567f51180b3834996a164/join/Cooking ERD.png -------------------------------------------------------------------------------- /join/Cooking data model DDL.sql: -------------------------------------------------------------------------------- 1 | create schema if not exists about_joins; 2 | 3 | create table about_joins.color (id integer primary key, name text, color_attr integer); 4 | create table about_joins.taste (id integer primary key, name text); 5 | create table about_joins.intensity (id integer primary key, intensity text); 6 | create table about_joins.category (id integer primary key, name text); 7 | create table about_joins.unit (id integer primary key, name text); 8 | create table about_joins.ingredient (id integer primary key, name text, category_id integer, color_id integer, taste_id integer, intensity_id integer, unit_id integer); 9 | create table about_joins.dish_recipe (id integer primary key, name text, instructions text, notes text); 10 | create table about_joins.recipe_ingredient (dish_id integer, ingredient_id integer, quantity numeric, notes text, primary key (dish_id, ingredient_id)); 11 | 12 | insert into about_joins.color 13 | values 14 | (10, 'червен', 1000), 15 | (11, 'зелен', 2000), 16 | (12, 'син', 3000), 17 | (13, 'циан', 4000), 18 | (14, 'магента', 5000), 19 | (15, 'жълт', 6000), 20 | (16, 'черен', 7000), 21 | (17, 'бял', 8000), 22 | (18, 'оранжев', 9000), 23 | (19, 'кафяв', 10000), 24 | (20, 'розов', 11000), 25 | (21, 'виолетов', 12000); 26 | 27 | insert into about_joins.taste 28 | values 29 | (1, 'сладък'), 30 | (2, 'солен'), 31 | (3, 'кисел'), 32 | (4, 'горчив'), 33 | (5, 'лют'), 34 | (6, 'неутрален'); 35 | 36 | insert into about_joins.intensity 37 | values 38 | (1, 'много слабо'), 39 | (2, 'слабо'), 40 | (3, 'умерено'), 41 | (4, 'силно'), 42 | (5, 'много силно'), 43 | (6, 'екстремално'); 44 | 45 | insert into about_joins.category 46 | values 47 | (1, 'зеленчуци'), 48 | (2, 'плодове'), 49 | (3, 'месо и колбаси'), 50 | (4, 'риба и морски дарове'), 51 | (5, 'варива'), 52 | (6, 'тестени и паста'), 53 | (7, 'подправки'), 54 | (8, 'мляко и млечни продукти'), 55 | (9, 'ядки'), 56 | (10, 'други'); 57 | 58 | insert into about_joins.unit 59 | values 60 | (1, 'брой'), 61 | (2, 'грам'), 62 | (3, 'литър'), 63 | (4, 'пакетче (както в "пакетче бакпулвер")'), 64 | (5, 'кофичка (както в "кофичка кисело мляко")'), 65 | (6, 'чаена лъжичка (както в "чаена лъжичка червен пипер")'), 66 | (7, 'кафена лъжичка (както в "кафена лъжичка захар")'), 67 | (8, 'щипка (както в "щипка сол")'); 68 | 69 | insert into about_joins.ingredient (id, "name", category_id, color_id, taste_id, intensity_id, unit_id) 70 | values 71 | (1, 'домат', 1, 10, 3, 2, 1), 72 | (2, 'лук', 1, 15, 5, 2, 1), 73 | (3, 'чесън', 1, 17, 5, 3, 1), 74 | (4, 'орех', 91, 19, 6, 92, 2), 75 | (5, 'черен пипер', 7, 16, 5, 4, 2), 76 | (6, 'яйце', null, 17, 6, null, 1), 77 | (7, 'кайма', 3, 10, null, null, 2), 78 | (8, 'олио', null, 15, null, null, 2), 79 | (9, 'кисело мляко', 8, 17, 3, 2, 5), 80 | (10, 'краставица', 1, 11, 3, 1, 1); 81 | 82 | ------------------------------------------------------------------------ 83 | 84 | select * from about_joins.color; 85 | select * from about_joins.taste; 86 | select * from about_joins.intensity; 87 | select * from about_joins.category; 88 | select * from about_joins.unit; 89 | select * from about_joins.ingredient; 90 | -------------------------------------------------------------------------------- /join/Joins.png: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/stefanov-sm/Database-XI/3d4c68199bb9cf0bee3567f51180b3834996a164/join/Joins.png -------------------------------------------------------------------------------- /join/README.md: -------------------------------------------------------------------------------- 1 | ## JOINS 2 | 3 | > [!IMPORTANT] 4 | > Probably the most important thing in the relational database domain 5 | > (i.e. cooking) :relaxed: 6 | 7 | See what's there [on the board](../On-the-board/2024-10-01.sql) 8 | 9 | ``` 10 | ::= [[AS] ] ;To be continued 11 | ::= 12 | [ 13 | INNER | 14 | LEFT [OUTER] | 15 | RIGHT [OUTER] | 16 | FULL [OUTER] | 17 | CROSS 18 | ] JOIN [LATERAL] 19 | 20 | ON 21 | ``` 22 | 23 | SQLite JOIN syntax diagram at [SQL As Understood By SQLite](https://devdoc.net/database/sqlite-3.0.7.2/lang_select.html) 24 | 25 | ![join-operator](https://github.com/user-attachments/assets/1d283a35-15bd-46e5-8c46-d7ca8e1c9204) 26 | 27 | You might have a look at [w3resource SQL tutorial](https://www.w3resource.com/sql/tutorials.php) and its [SQL JOINS](https://www.w3resource.com/sql/joins/sql-joins.php) section. 28 | -------------------------------------------------------------------------------- /miscellaneous/About ETL/about-ETL.sql: -------------------------------------------------------------------------------- 1 | -- Extract-Transform-Load (ETL) and ELT 2 | 3 | /* Fixed width field format 4 | 123456ABCDV123ABCDEF1234567890AНякакъв текст А 5 | 223456ABCDW223abcdef1234567890AДруг текст Б 6 | 323456ABCDX323ABCDEF1234567890AНякакъв текст В 7 | 423456ABCDY423abcdef1234567890AДруг текст Г 8 | 523456ABCDZ523ABCDEF1234567890AНякакъв текст Д 9 | */ 10 | 11 | -- Data extraction using COPY command 12 | create temporary table fw_tbl(fl text); 13 | copy fw_tbl from 'C:\foreign_data\fl_data.txt' 14 | with (format 'csv', delimiter E'\b', encoding 'Windows-1251'); 15 | 16 | -- using a foreign table 17 | create foreign table fw_ftbl (fl text) 18 | server file_server 19 | options 20 | ( 21 | filename 'C:\foreign_data\fl_data.txt', 22 | format 'csv', delimiter E'\b', encoding 'Windows-1251' 23 | ); 24 | 25 | select * from fw_tbl; 26 | select * from fw_ftbl; 27 | 28 | /* or using INSERT 29 | insert into fw_tbl 30 | values ('123456ABCDZ123ABCDEF1234567890AНякакъв текст А'), ('223456ABCDZ123ABCDEF1234567890AДруг текст Б'), 31 | ('323456ABCDZ123ABCDEF1234567890AНякакъв текст В'), ('423456ABCDZ123ABCDEF1234567890AДруг текст Г'), 32 | ('523456ABCDZ123ABCDEF1234567890AНякакъв текст Д'); 33 | */ 34 | 35 | 36 | -- drop function if exists fw_regexp; 37 | -------------------------------------------------------------------------------- 38 | create or replace function fw_regexp(pos_list text) 39 | returns text language sql immutable as 40 | $$ 41 | select '^' 42 | || string_agg(coalesce('(.{'||len||'})', '(.*)'), null order by pos) 43 | || '$' 44 | from 45 | ( 46 | select pos, lead(pos) over (order by pos) - pos as len 47 | from unnest(string_to_array(pos_list, ',')::integer[]) as t(pos) 48 | ) as t; 49 | $$; 50 | 51 | -- Unit test 52 | select fw_regexp('1, 7, 12, 15, 11, 32, 21'); 53 | 54 | -- drop function if exists fw_array; 55 | -------------------------------------------------------------------------------- 56 | create or replace function fw_array(fwdata text, fwregexp text) 57 | returns text[] language sql immutable as 58 | $$ 59 | select regexp_match(fwdata, fwregexp); 60 | $$; 61 | 62 | 63 | /* Two more things to be defined: 64 | - the fields' start offsets, i.e. '1, 7, 12, 15, 11, 32, 21' in this example, 65 | an easy thing to do with a text editor 66 | - the column names and data types 67 | */ 68 | -- data transformation in the SELECT expression list 69 | -- data cleansing in the WHERE clause 70 | create or replace temporary view fw_view as 71 | select arr[1]::numeric as apple, arr[2] as pear, arr[3] as peach, 72 | arr[4]::integer as lemon, arr[5] as orange, arr[6] as plum, 73 | arr[7] as cherry 74 | from 75 | ( 76 | select fw_array(fl, fw_regexp('1, 7, 12, 15, 11, 32, 21')) as arr 77 | from fw_ftbl 78 | ) as t 79 | where not arr[7] ~* 'друг'; 80 | 81 | select * from fw_view; 82 | 83 | discard all; 84 | -------------------------------------------------------------------------------- /miscellaneous/About ETL/fl_data.txt: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/stefanov-sm/Database-XI/3d4c68199bb9cf0bee3567f51180b3834996a164/miscellaneous/About ETL/fl_data.txt -------------------------------------------------------------------------------- /miscellaneous/About ETL/mixed cultures.csv: -------------------------------------------------------------------------------- 1 | dish,price,is_french 2 | Попска яхния, 15.30, 0 3 | Creme caramel, "10,50", true 4 | Fish and chips, 15.00, false 5 | Creme brulee, "6,20", yes 6 | Mercimek Çorbası, 12.00, no 7 | -------------------------------------------------------------------------------- /miscellaneous/Converting JSON documents to relational tables/Formatted JSONtest.zip: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/stefanov-sm/Database-XI/3d4c68199bb9cf0bee3567f51180b3834996a164/miscellaneous/Converting JSON documents to relational tables/Formatted JSONtest.zip -------------------------------------------------------------------------------- /miscellaneous/Converting JSON documents to relational tables/Readme.md: -------------------------------------------------------------------------------- 1 | ### [Converting JSON documents to relational tables](https://www.postgresonline.com/journal/index.php?/archives/420-Converting-JSON-documents-to-relational-tables.html) 2 | ### A handy alternative approach. Demo with a 32MB JSON document file 3 | > [!NOTE] 4 | > Ctrl+A and Ctrl+B are **very** unlikely to appear unescaped in a real-life data file 5 | ```sql 6 | -- drop foreign table if exists json_data 7 | 8 | create foreign table json_data (jsonline text) 9 | server file_server 10 | options (filename 'C:/foreign_data/test.json', format 'csv', delimiter e'\x01', quote e'\x02'); 11 | 12 | create table jsontable as 13 | with t(jdata) as ( 14 | select string_agg(jsonline, '')::jsonb 15 | from json_data 16 | ) 17 | select jsonb_array_elements(jdata) j 18 | from t; 19 | 20 | select * from jsontable; 21 | ``` 22 | An example using `json_table` function 23 | > [!NOTE] 24 | > Apply the above approach & use `json_table` for a real-life case 25 | ```sql 26 | create temporary table the_table (js jsonb); 27 | -- truncate table the_table; 28 | 29 | insert into the_table values ( 30 | '{ 31 | "favorites":[ 32 | { 33 | "kind":"comedy", 34 | "films":[{"title":"Bananas", "director":"Woody Allen", "rating":10}, 35 | {"title":"The Dinner Game", "director":"Francis Veber", "rating":9}] 36 | }, 37 | { 38 | "kind":"horror", 39 | "films":[{"title":"Psycho", "director":"Alfred Hitchcock", "rating":8}, 40 | {"title":"То", "director":"Стивън Кинг", "rating":8}] 41 | }, 42 | { 43 | "kind":"thriller", 44 | "films":[{"title": "Vertigo", "director": "Alfred Hitchcock", "rating": 7}] 45 | }, 46 | { 47 | "kind":"drama", 48 | "films":[{"title": "Yojimbo", "director": "Akira Kurosawa", "rating": 6}] 49 | } 50 | ] 51 | }'); 52 | 53 | select * from the_table; 54 | 55 | select jtable.* from the_table 56 | cross join lateral json_table ( 57 | js, '$.favorites[*]' 58 | columns ( 59 | id for ordinality, 60 | kind text path '$.kind', 61 | nested path '$.films[*]' 62 | columns ( 63 | title text path '$.title', 64 | director text path '$.director', 65 | rating integer path '$.rating' 66 | ) 67 | ) 68 | ) as jtable; 69 | -------------------------------------------------------------------------------- /miscellaneous/Custom aggregate.md: -------------------------------------------------------------------------------- 1 | ### Custom aggregate function - [rms](https://en.wikipedia.org/wiki/Root_mean_square) as an illustration 2 | > [!CAUTION] 3 | > **Use custom aggregates with care. Compatibility & portability issues may arise** 4 | > **Only available in PostgreSQL and Oracle** 5 | 6 | 7 | ```sql 8 | create type rms_state_t as (cnt integer, accumulator numeric); 9 | 10 | create or replace function rms_state_f(rms_state rms_state_t, rv numeric) 11 | returns rms_state_t language sql as 12 | $$ 13 | select case 14 | when rv is null then rms_state 15 | when rms_state is null then (1, rv * rv)::rms_state_t 16 | else (rms_state.cnt + 1, rms_state.accumulator + rv * rv)::rms_state_t 17 | end; 18 | $$; 19 | 20 | create or replace function rms_final_f(final_state rms_state_t) 21 | returns numeric language sql as 22 | $$ 23 | select sqrt(final_state.accumulator / final_state.cnt); 24 | $$; 25 | 26 | create or replace aggregate rms(numeric) 27 | ( 28 | STYPE = rms_state_t, 29 | SFUNC = rms_state_f, 30 | FINALFUNC = rms_final_f 31 | ); 32 | ``` 33 | #### Demo 34 | ```sql 35 | with t(v) as ( 36 | values (10),(2),(3),(44),(5) 37 | ) 38 | select rms(v) from t; 39 | ``` 40 | Result 20.366639 41 | -------------------------------------------------------------------------------- /miscellaneous/Custom operators.md: -------------------------------------------------------------------------------- 1 | ## User defined [operators](https://www.postgresql.org/docs/current/sql-createoperator.html) in PostgreSQL 2 | #### (Oracle is similar with a different [syntax](https://docs.oracle.com/en/database/oracle/oracle-database/21/sqlrf/CREATE-OPERATOR.html)) 3 | . 4 | > [!CAUTION] 5 | > **Use custom operators with care. Compatibility & portability issues may arise** 6 | 7 | . 8 | 9 | ![MSSQL](https://github.com/user-attachments/assets/20c7a903-ef31-4cf8-86da-ff696485f0dc) 10 | ### String concatenation MS-SQL Server style operator 11 | ```sql 12 | create or replace function text_concat (a text, b text) 13 | returns text language sql immutable strict parallel safe as 14 | $$ 15 | select a || b; 16 | $$; 17 | 18 | create operator + 19 | ( 20 | leftarg = text, rightarg = text, function = text_concat 21 | ); 22 | 23 | select 'Hello' + ' plus ' + 'operator' + '!'; 24 | 25 | -- Cleanup 26 | 27 | drop operator + (text, text); 28 | drop function text_concat; 29 | 30 | ``` 31 | ![resistors-in-parallel](https://github.com/user-attachments/assets/39d82858-de23-4bed-9253-8ba6bc95af96) ![capacitors](https://github.com/user-attachments/assets/c9af2b85-5e3b-4d3e-a3c8-47cb1d8724a5) 32 | ### Resistors in parallel, capacitors in series operator 33 | ```sql 34 | create or replace function rpar(r1 numeric, r2 numeric) 35 | returns numeric language sql immutable strict parallel safe as 36 | $$ 37 | select (r1 * r2)/(r1 + r2); 38 | $$; 39 | 40 | create operator || 41 | ( 42 | leftarg = numeric, rightarg = numeric, function = rpar 43 | ); 44 | 45 | select 12 || 10; 46 | 47 | -- Cleanup 48 | 49 | drop operator || (numeric, numeric); 50 | drop function rpar; 51 | ``` 52 | ### JSONB scalar to text unary prefix operator 53 | > [!NOTE] 54 | > **Unary suffix operators are not supported** 55 | ```sql 56 | create or replace function jsonb_text(j jsonb) 57 | returns text immutable strict language sql as 58 | $$ 59 | select j #>> '{}' 60 | $$; 61 | 62 | create operator >> (rightarg = jsonb, function = jsonb_text); 63 | 64 | -- Cleanup 65 | 66 | drop operator >> (none, jsonb); -- Note "none" as the type of the missing leftarg 67 | drop function jsonb_text; 68 | ``` 69 | #### Demo 70 | ```sql 71 | with t(j) as ( 72 | values ('{"tx":"A text", "nested":{"x":1, "y": "one \"way\""}}'::jsonb), 73 | ('{"tx":"B text", "nested":{"x":2, "y": "two \"times\""}}'::jsonb) 74 | ) 75 | select 76 | j['tx'] as tx_as_json, 77 | >>j['tx'] as tx_as_text, 78 | j['nested']['x'] as x_as_json, 79 | j['nested']['y'] as y_as_json, 80 | >>j['nested']['y'] as y_as_text 81 | from t; 82 | ``` 83 | 84 | -------------------------------------------------------------------------------- /miscellaneous/Discrepancies/Martin.Grigorov/HW-Script-1.sql: -------------------------------------------------------------------------------- 1 | CREATE TABLE IF NOT EXISTS table1 ( 2 | id SERIAL PRIMARY KEY, 3 | column1 INTEGER, 4 | column2 TEXT, 5 | column3 NUMERIC, 6 | column4 DATE 7 | ); 8 | 9 | CREATE TABLE IF NOT EXISTS table2 ( 10 | id SERIAL PRIMARY KEY, 11 | column1 INTEGER, 12 | column2 TEXT, 13 | column3 NUMERIC, 14 | column4 DATE 15 | ); 16 | 17 | INSERT INTO table1 (column1, column2, column3, column4) VALUES 18 | (1, 'sample text', 12.34, '2023-01-01'), 19 | (2, 'test', 45.67, '2023-02-01'); 20 | 21 | INSERT INTO table2 (column1, column2, column3, column4) VALUES 22 | (1, 'sample text', 12.34, '2023-01-01'), 23 | (2, 'different text', 45.00, '2023-02-15'); 24 | 25 | -------------------------------------------------------------------------------- /miscellaneous/Discrepancies/Martin.Grigorov/HW-Script-2.sql: -------------------------------------------------------------------------------- 1 | DO $$ 2 | DECLARE 3 | col_name RECORD; 4 | sql_query TEXT := 'SELECT t1.id'; 5 | discrepancy_sql TEXT := ''; 6 | BEGIN 7 | FOR col_name IN 8 | SELECT column_name 9 | FROM information_schema.columns 10 | WHERE table_name = 'table1' AND column_name <> 'id' 11 | LOOP 12 | sql_query := sql_query || ', 13 | CASE 14 | WHEN t1.' || col_name.column_name || ' IS DISTINCT FROM t2.' || col_name.column_name || ' 15 | THEN ''Difference in ' || col_name.column_name || ': '' || COALESCE(t1.' || col_name.column_name || '::TEXT, ''NULL'') 16 | || '' vs '' || COALESCE(t2.' || col_name.column_name || '::TEXT, ''NULL'') 17 | ELSE NULL 18 | END AS discrepancy_' || col_name.column_name; 19 | END LOOP; 20 | 21 | sql_query := sql_query || ' FROM table1 t1 FULL OUTER JOIN table2 t2 ON t1.id = t2.id'; 22 | 23 | FOR col_name IN 24 | SELECT column_name 25 | FROM information_schema.columns 26 | WHERE table_name = 'table1' AND column_name <> 'id' 27 | LOOP 28 | discrepancy_sql := discrepancy_sql || 29 | ' t1.' || col_name.column_name || ' IS DISTINCT FROM t2.' || col_name.column_name || ' OR'; 30 | END LOOP; 31 | 32 | IF length(discrepancy_sql) > 0 THEN 33 | discrepancy_sql := left(discrepancy_sql, length(discrepancy_sql) - 3); 34 | sql_query := sql_query || ' WHERE ' || discrepancy_sql; 35 | END IF; 36 | 37 | BEGIN 38 | EXECUTE 'DROP VIEW IF EXISTS comparison_view'; 39 | EXCEPTION 40 | WHEN OTHERS THEN 41 | NULL; 42 | END; 43 | 44 | EXECUTE 'CREATE VIEW comparison_view AS ' || sql_query; 45 | 46 | RAISE NOTICE 'Generated SQL: %', sql_query; 47 | 48 | END $$; 49 | -------------------------------------------------------------------------------- /miscellaneous/Discrepancies/S. Stefanov/discrepancies.sql: -------------------------------------------------------------------------------- 1 | -- drop table if exists discrepancies; 2 | create table discrepancies 3 | ( 4 | id integer, 5 | "A.A.11" integer, "B.B.32" integer, "C.C.17" integer, "D.D.59" integer, "E.E.76" integer, 6 | "A.F.11" integer, "B.G.32" integer, "C.H.17" integer, "D.I.59" integer, "E.J.76" integer, 7 | "A.K.11" text, "B.L.32" text, "C.M.17" text, "D.N.59" text, 8 | "E.O.11" text, "F.P.32" text, "G.Q.17" text, "H.R.59" text, 9 | "A.S.11" text, "B.T.32" text, "C.U.17" text, "D.V.59" text, 10 | "E.W.11" text, "F.X.32" text, "G.Y.17" text, "H.Z.59" text, 11 | tablename text 12 | ); 13 | 14 | insert into discrepancies values 15 | (1, 101, 102, 103, 104, 105, 106, 107, 108, 109, 110, 'X101', 'X102', 'X103', 'X104', 'X105', 'X106', 'X107', 'X108', 'X109', 'X110', 'Y101', 'Y102', 'Y103', 'Y104', 'Y105', 'Y106', 'table_A'), 16 | (1, 101, 102, 103, 104, 115, 106, 107, 108, 109, 110, 'X101', 'X102', 'X103', 'X104', 'X115', 'X106', 'X107', 'X108', 'X109', 'X110', 'Y101', 'Y102', 'Y103', 'Y104', 'Y105', 'Y106', 'table_B'), 17 | (2, 201, 202, 203, 204, 205, 226, 207, 208, 209, 210, 'X201', 'X202', 'X203', 'X204', 'X205', 'X206', 'X207', 'X208', 'X209', 'X210', 'Y201', 'Y202', 'Y203', 'Y204', 'Y205', 'Y206', 'table_A'), 18 | (2, 201, 202, 203, 204, 205, 206, 207, 208, 209, 210, 'X201', 'X202', 'X203', 'X204', 'X205', 'X226', 'X207', 'X208', 'X209', 'X210', 'Y201', 'Y202', 'Y203', 'Y204', 'Y205', 'Y206', 'table_B'), 19 | (3, 301, 302, 303, 304, 305, 306, 337, 308, 309, 310, 'X301', 'X302', 'X303', 'X304', 'X305', 'X306', 'X307', 'X308', 'X309', 'X310', 'Y301', 'Y302', 'Y303', 'Y304', 'Y305', 'Y306', 'table_A'), 20 | (3, 301, 302, 303, 304, 305, 306, 307, 308, 309, 310, 'X301', 'X302', 'X303', 'X304', 'X305', 'X306', 'X307', 'X308', 'X309', 'X310', 'Y301', 'Y302', 'Y303', 'Y304', 'Y305', 'Y336', 'table_B'), 21 | (4, 401, 402, 403, 404, 405, 406, 407, 448, 409, 410, 'X401', 'X402', 'X403', 'X404', 'X405', 'X406', 'X407', 'X408', 'X409', 'X410', 'Y401', 'Y402', 'Y403', 'Y404', 'Y405', 'Y406', 'table_A'), 22 | (4, 401, 402, 403, 404, 405, 406, 407, 408, 409, 410, 'X401', 'X402', 'X403', 'X404', 'X405', 'X406', 'X407', 'X408', 'X409', 'X410', 'Y411', 'Y402', 'Y403', 'Y404', 'Y405', 'Y406', 'table_B'), 23 | (5, 501, 502, 503, 504, 505, 506, 507, 508, 509, 510, 'X511', 'X502', 'X503', 'X504', 'X505', 'X506', 'X507', 'X508', 'X509', 'X510', 'Y501', 'Y502', 'Y503', 'Y504', 'Y505', 'Y506', 'table_A'), 24 | (5, 501, 502, 503, 504, 505, 506, 507, 508, 559, 510, 'X501', 'X502', 'X503', 'X504', 'X505', 'X506', 'X507', 'X508', 'X509', 'X510', 'Y501', 'Y502', 'Y503', 'Y504', 'Y505', 'Y506', 'table_B'); 25 | 26 | 27 | with t as 28 | ( 29 | select id, 30 | to_jsonb(nth_value(dt, 1) over w) fv, 31 | to_jsonb(nth_value(dt, 2) over w) lv 32 | from discrepancies dt 33 | window w as ( 34 | partition by id order by tablename 35 | rows between unbounded preceding and current row) 36 | ) 37 | select t.id as "Row ID", lat.* 38 | from t 39 | cross join lateral 40 | ( 41 | select a.column_name as "Column", 42 | a.value as "Value A", 43 | b.value as "Value B" 44 | from jsonb_each(fv) as a(column_name, value) 45 | join jsonb_each(lv) as b(column_name, value) 46 | on a.column_name = b.column_name 47 | where a.value <> b.value -- and a.column_name <> 'tablename' 48 | ) as lat 49 | where lv is not null; 50 | 51 | 52 | -- Minimalistic 53 | 54 | with t as 55 | ( 56 | select id, 57 | min(to_jsonb(discrepancies)::text)::jsonb fv, 58 | max(to_jsonb(discrepancies)::text)::jsonb lv 59 | from discrepancies group by id 60 | ) 61 | select t.id row_id, l.* 62 | from t, lateral 63 | ( 64 | select a.column_name, a.value value_a, b.value value_b 65 | from jsonb_each_text(fv) a(column_name, value) 66 | join jsonb_each_text(lv) b(column_name, value) 67 | on a.column_name = b.column_name 68 | where a.value <> b.value 69 | ) l 70 | -- place tablename on top of each row_id - group of records 71 | order by row_id, (column_name != 'tablename'), column_name; 72 | 73 | -------------------------------------------------------------------------------- /miscellaneous/Discrepancies/Svetoslav.XI-V/Discrepancies.sql: -------------------------------------------------------------------------------- 1 | CREATE OR REPLACE FUNCTION compare_rows_by_id(p_table_name text) 2 | RETURNS TABLE (id bigint, compared_column text, value1 text, value2 text, comes_from1 text, comes_from2 text) AS $$ 3 | DECLARE 4 | rec RECORD; 5 | col_info RECORD; 6 | sql_query text; 7 | BEGIN 8 | FOR rec IN EXECUTE format('SELECT id::bigint AS id FROM %I GROUP BY id HAVING COUNT(*) > 0', p_table_name) 9 | LOOP 10 | FOR col_info IN 11 | SELECT c.column_name, c.data_type 12 | FROM information_schema.columns AS c 13 | WHERE c.table_name = p_table_name AND c.column_name NOT IN ('id', 'comes_from') 14 | LOOP 15 | sql_query := format( 16 | 'SELECT id::bigint, ' || 17 | 'MIN(%s)::text AS value1, ' || 18 | 'MAX(%s)::text AS value2, ' || 19 | 'MIN(comes_from)::text AS comes_from1, ' || 20 | 'MAX(comes_from)::text AS comes_from2 ' || 21 | 'FROM %I ' || 22 | 'WHERE id = %L ' || 23 | 'GROUP BY id ' || 24 | 'HAVING MIN(%s) IS DISTINCT FROM MAX(%s)', 25 | 26 | CASE 27 | WHEN col_info.data_type IN ('character varying', 'text', 'character') 28 | THEN format('TRIM(%I)', col_info.column_name) 29 | ELSE col_info.column_name 30 | END, 31 | 32 | CASE 33 | WHEN col_info.data_type IN ('character varying', 'text', 'character') 34 | THEN format('TRIM(%I)', col_info.column_name) 35 | ELSE col_info.column_name 36 | END, 37 | 38 | p_table_name, 39 | rec.id::bigint, 40 | 41 | col_info.column_name, 42 | col_info.column_name 43 | ); 44 | 45 | FOR rec IN EXECUTE sql_query 46 | LOOP 47 | RETURN QUERY SELECT rec.id::bigint, col_info.column_name::text, rec.value1, rec.value2, rec.comes_from1, rec.comes_from2; 48 | END LOOP; 49 | END LOOP; 50 | END LOOP; 51 | END; 52 | $$ LANGUAGE plpgsql; 53 | 54 | 55 | 56 | -- Drop the existing discrepancy table if it exists 57 | DROP TABLE IF EXISTS discrepancy_table; 58 | 59 | -- Create the discrepancy_table with data from bigtablea and bigtableb 60 | CREATE TEMP TABLE discrepancy_table AS ( 61 | ( 62 | SELECT *, 'tableA' AS "comes_from" 63 | FROM bigtablea 64 | EXCEPT ALL 65 | SELECT *, 'tableA' AS "comes_from" 66 | FROM bigtableb 67 | ) 68 | UNION ALL 69 | ( 70 | SELECT *, 'tableB' AS "comes_from" 71 | FROM bigtableb 72 | EXCEPT ALL 73 | SELECT *, 'tableB' AS "comes_from" 74 | FROM bigtablea 75 | ) 76 | ); 77 | 78 | --select * from discrepancy_table ORDER BY id; 79 | 80 | -- Call the function with sorting by id and compared_column 81 | SELECT * FROM compare_rows_by_id('discrepancy_table') 82 | ORDER BY id, compared_column; -------------------------------------------------------------------------------- /miscellaneous/JSONB misc.sql: -------------------------------------------------------------------------------- 1 | -------------------------------------------------------------------------------- 2 | create or replace function jsonb_text(j jsonb) 3 | returns text immutable strict language sql as 4 | $$ 5 | select j #>> '{}' 6 | $$; 7 | 8 | -------------------------------------------------------------------------------- 9 | -- unit test 10 | select ('{"key":"X100"}'::jsonb)['key'], 11 | jsonb_text(('{"key":"X100"}'::jsonb)['key']); 12 | 13 | 14 | -------------------------------------------------------------------------------- 15 | create or replace function jsonpath_lint(jtext text, jpath text) 16 | returns table (result_value text, result_type text) immutable language plpgsql as 17 | $$ 18 | declare 19 | etext text; edetails text; ehint text; 20 | LF constant text := e'\n'; ERR constant text := '*** Error ***'; 21 | begin 22 | return query 23 | with t as (select jsonb_path_query(jtext::jsonb, jpath::jsonpath) res) 24 | select res::text, coalesce(jsonb_typeof(res)::text, 'NULL') from t; 25 | exception when others then 26 | get stacked diagnostics 27 | etext := MESSAGE_TEXT, edetails := PG_EXCEPTION_DETAIL, ehint := PG_EXCEPTION_HINT; 28 | return query 29 | select 30 | concat_ws(LF, ERR, nullif(etext, ''), nullif(edetails, ''), nullif(ehint, '')), 31 | null; 32 | end; 33 | $$; 34 | 35 | -------------------------------------------------------------------------------- 36 | create or replace function jsonpath_lint_html(text, text) 37 | returns text language sql immutable as 38 | $$ 39 | select '
'||
40 |   string_agg(concat_ws(' ', r.result_value, '('||r.result_type||')'), e'\n')||
41 |   '
' 42 | from jsonpath_lint($1, $2) as r 43 | $$; 44 | 45 | -------------------------------------------------------------------------------- 46 | -- unit test,
 HTML output
47 | select jsonpath_lint_html('{"key":[11,12,13,14,15], "value":{"current":false}}', '$.value.current');
48 | 


--------------------------------------------------------------------------------
/miscellaneous/Refresh ECB forex.php:
--------------------------------------------------------------------------------
 1 |  open($tempZipFile);
15 |   $zipEngine -> extractTo(FOREIGN_DATA_FOLDER);
16 |   $zipEngine -> close();
17 |   unlink($tempZipFile);
18 | }
19 | catch (Throwable $err) {
20 |   file_put_contents(__DIR__.'/ECB.errorlog.txt',
21 |                     date('Y-m-d H:i:s - ').($err -> getMessage()).PHP_EOL, 
22 |                     FILE_APPEND);
23 | };
24 | 


--------------------------------------------------------------------------------
/miscellaneous/Table for recursive CTE.sql:
--------------------------------------------------------------------------------
 1 | create table org_chart
 2 | (
 3 |  id integer not null primary key,
 4 |  full_name text not null,
 5 |  manager_id integer references org_chart(id),
 6 |  other_details jsonb not null default '{}'
 7 | );
 8 | 
 9 | -- truncate table org_chart;
10 | 
11 | insert into org_chart (id, full_name, manager_id)
12 | values 
13 | (101, 'CEO CE001', null),	-- Chief executive officer
14 | (201, 'CTO_CT201', 101),	-- Chief technical officer, reports to CEO
15 | (202, 'CFO_CF202', 101),	-- Chief financial officer, reports to CEO
16 | (203, 'COO_CO203', 101),	-- Chief operations officer, reports to CEO
17 | (204, 'CMO_CF204', 101),	-- Chief marketing officer, reports to CEO
18 | (205, 'CIO_CO205', 101),	-- Chief information officer, reports to CEO
19 | (301, 'MTD01_MT301', 201),	-- Manager of technical department 01, reports to CTO
20 | (302, 'MTD02_MT302', 201),	-- Manager of technical department 02, reports to CTO
21 | (303, 'MTD03_MT303', 201),	-- Manager of technical department 03, reports to CTO
22 | (311, 'MFD01_MF311', 202),	-- Manager of financial department 01, reports to CFO
23 | (312, 'MFD02_MF312', 202),	-- Manager of financial department 02, reports to CFO
24 | (321, 'MID01_MI321', 205),	-- Manager of IT department 01, reports to CIO
25 | (322, 'MID02_MI322', 205),	-- Manager of IT department 02, reports to CIO
26 | (323, 'MID03_MI323', 205),	-- Manager of IT department 03, reports to CIO
27 | (331, 'MOD01_MO331', 203),	-- Manager of operations department 01, reports to COO
28 | (332, 'MOD02_MO332', 203),	-- Manager of operations department 02, reports to COO
29 | (333, 'MOD03_MO333', 203),	-- Manager of operations department 03, reports to COO
30 | (341, 'MMD01_MM341', 204);	-- Manager of marketing department 01, reports to CMO
31 | 
32 | insert into org_chart(id, full_name, manager_id)
33 | with t as
34 | (
35 |  select 
36 |    ('{301,302,303,311,312,321,322,323,331,332,333,341}'::integer[])[(random()*97)::integer % 11 + 1] as v,
37 |    rn
38 |  from generate_series(1, 150) as t(rn)
39 | )
40 | select 1000 + rn, 'EMPLOYEE.'||(2000 + rn)::text, v from t;
41 | 
42 | -- select * from org_chart;
43 | 
44 | 
45 | 
46 | -- So here we go. Who works for $MANAGER_ID (incl. himself)?
47 | with RECURSIVE t as 
48 | (
49 |  select * from org_chart where id = $MANAGER_ID
50 |  UNION ALL 
51 |  select org_chart.* from t, org_chart 
52 |   -- the magic happens here 
53 |   where org_chart.manager_id = t.id 
54 | )
55 | select * from t;
56 | 
57 | -- or basically the same with JOIN
58 | with RECURSIVE t as 
59 | (
60 |  select * from org_chart where id = $MANAGER_ID
61 |  UNION ALL 
62 |  select org_chart.* 
63 |  from org_chart inner join t on org_chart.manager_id = t.id 
64 | )
65 | select * from t;
66 | 
67 | 


--------------------------------------------------------------------------------
/miscellaneous/cooking/Касърова 1933.pdf:
--------------------------------------------------------------------------------
https://raw.githubusercontent.com/stefanov-sm/Database-XI/3d4c68199bb9cf0bee3567f51180b3834996a164/miscellaneous/cooking/Касърова 1933.pdf


--------------------------------------------------------------------------------
/miscellaneous/food deliveries/Lunch A.sql:
--------------------------------------------------------------------------------
  1 | -- Създаване на таблица за съставки
  2 | --CREATE TABLE IF NOT EXISTS Ingredients (
  3 | --    id SERIAL PRIMARY KEY,
  4 | --    name TEXT NOT NULL
  5 | --);
  6 | --
  7 | -- Създаване на таблица за рецепти
  8 | --CREATE TABLE IF NOT EXISTS Recipe (
  9 | --    dish_id INT PRIMARY KEY,
 10 | --    dish_name TEXT NOT NULL
 11 | --);
 12 | --
 13 | -- Създаване на таблица за съставки в рецепти (много към много)
 14 | --CREATE TABLE IF NOT EXISTS Ingredient_Recipe (
 15 | --    recipe_id INT REFERENCES Recipe(dish_id),
 16 | --    ingredient_id INT REFERENCES Ingredients(id),
 17 | --    quantity NUMERIC NOT NULL
 18 | --);
 19 | --
 20 | -- Създаване на таблица за менюта
 21 | --CREATE TABLE IF NOT EXISTS Menu (
 22 | --    id INT PRIMARY KEY,
 23 | --    menu_date DATE NOT NULL,
 24 | --    first_course INT REFERENCES Recipe(dish_id),
 25 | --    second_course INT REFERENCES Recipe(dish_id),
 26 | --    third_course INT REFERENCES Recipe(dish_id)
 27 | --);
 28 | 
 29 | -- Вкарване на примерни съставки
 30 | --INSERT INTO Ingredients (name) VALUES 
 31 | --('Cucumber'), 
 32 | --('Yogurt'), 
 33 | --('Garlic'), 
 34 | --('Rice'), 
 35 | --('Chicken'), 
 36 | --('Tomato'),
 37 | --('Onion'),
 38 | --('Olive oil');
 39 | --
 40 | ---- Вкарване на примерни рецепти
 41 | ----INSERT INTO Recipe (dish_id, dish_name) VALUES 
 42 | --(1, 'Tarator'), 
 43 | --(2, 'Pile s oriz'), 
 44 | --(3, 'Chicken and Rice Soup');
 45 | 
 46 | -- Вкарване на съставките за рецептите
 47 | --INSERT INTO Ingredient_Recipe (recipe_id, ingredient_id, quantity) VALUES 
 48 | --(1, 1, 200),  -- Tarator: 200g от краставица
 49 | --(1, 2, 300),  -- Tarator: 300g от кисело мляко
 50 | --(1, 3, 5),    -- Tarator: 5 скилидки чесън
 51 | --(2, 4, 200),  -- Pile s oriz: 200g от ориз
 52 | --(2, 5, 300),  -- Pile s oriz: 300g от пиле
 53 | --(3, 6, 150),  -- Chicken and Rice Soup: 150g от домат
 54 | --(3, 7, 50),   -- Chicken and Rice Soup: 50g от лук
 55 | --(3, 4, 200),  -- Chicken and Rice Soup: 200g от ориз
 56 | --(3, 5, 300),  -- Chicken and Rice Soup: 300g от пиле
 57 | --(3, 8, 30);   -- Chicken and Rice Soup: 30g от зехтин
 58 | --
 59 | ---- Вкарване на примерен обяд (меню)
 60 | --INSERT INTO Menu (id, menu_date, first_course, second_course, third_course) VALUES
 61 | --(1, current_date + 1, 1, 2, 3);  -- Меню с Tarator, Pile s oriz, Chicken and Rice Soup
 62 | 
 63 | -- Запитване за намиране на използваните съставки и тяхното общо количество за менюто на деня
 64 | SELECT 
 65 |     i.name,  -- Избиране на името на съставката
 66 |     SUM(ir.quantity) AS total_quantity  -- Изчисляване на общото количество на всяка съставка
 67 | FROM 
 68 |     Menu m
 69 | JOIN 
 70 |     Recipe r1 ON m.first_course = r1.dish_id  -- Свързване на менюто с първото ястие
 71 | JOIN 
 72 |     Ingredient_Recipe ir ON r1.dish_id = ir.recipe_id  -- Свързване на рецептата с нейните съставки
 73 | JOIN 
 74 |     Ingredients i ON ir.ingredient_id = i.id  -- Свързване на съставката по нейните идентификатори
 75 | WHERE 
 76 |     m.menu_date = current_date + 1  -- Филтриране на менюто за утрешния ден
 77 | GROUP BY 
 78 |     i.name  -- Групиране по името на съставката, за да се обобщи количеството
 79 | UNION ALL  -- Използваме UNION ALL за обединяване на резултатите от следващите два селекта
 80 | 
 81 | SELECT 
 82 |     i.name, 
 83 |     SUM(ir.quantity) AS total_quantity
 84 | FROM 
 85 |     Menu m
 86 | JOIN 
 87 |     Recipe r2 ON m.second_course = r2.dish_id  -- Свързване на менюто с второто ястие
 88 | JOIN 
 89 |     Ingredient_Recipe ir ON r2.dish_id = ir.recipe_id
 90 | JOIN 
 91 |     Ingredients i ON ir.ingredient_id = i.id
 92 | WHERE 
 93 |     m.menu_date = current_date + 1
 94 | GROUP BY 
 95 |     i.name
 96 | 
 97 | UNION ALL  -- Продължаваме с обединяването на резултатите за третото ястие
 98 | 
 99 | SELECT 
100 |     i.name, 
101 |     SUM(ir.quantity) AS total_quantity
102 | FROM 
103 |     Menu m
104 | JOIN 
105 |     Recipe r3 ON m.third_course = r3.dish_id  -- Свързване на менюто с третото ястие
106 | JOIN 
107 |     Ingredient_Recipe ir ON r3.dish_id = ir.recipe_id
108 | JOIN 
109 |     Ingredients i ON ir.ingredient_id = i.id
110 | WHERE 
111 |     m.menu_date = current_date + 1
112 | GROUP BY 
113 |     i.name;
114 | 
115 | --select * from ingredients;
116 | 


--------------------------------------------------------------------------------
/miscellaneous/food deliveries/Lunch B.sql:
--------------------------------------------------------------------------------
 1 | create table product(
 2 | id integer primary key not null,
 3 | --parent_item_id integer references menu_item(id),
 4 | is_primary boolean not null default true,
 5 | name text,
 6 | other_details jsonb not null default '{}'
 7 | );
 8 | 
 9 | truncate table product_bridge;
10 | 
11 | create table product_bridge(
12 | 	id serial primary key not null,
13 | 	product_id integer references product(id),
14 | 	part_of_id integer references product(id),
15 | 	quantity numeric,
16 | 	other_details jsonb not null default '{}'
17 | --constraint mip_pk primary key (item_id, product_id)
18 | );
19 | 
20 | insert into product(id, is_primary, name)
21 | values (0,true ,'potato'),
22 | (1, true ,'onion'),
23 | (2, true, 'pork'),
24 | (10, false, 'potato salad'),
25 | (11, false, 'porkchop'),
26 | (12, false, 'porkpotato meal');
27 | 
28 | insert into product_bridge(product_id, part_of_id,quantity)
29 | values (0,10, 5),
30 | (1, 10, 1),
31 | (2,11, 1),
32 | (10,12,1),
33 | (11,12,1);
34 | 
35 | with recursive cooking as 
36 | (
37 | 	select *, 2::numeric as "quantity" from product
38 | 	where id = 12
39 | 	union ALL
40 | 	
41 | 	select p.*, c.quantity * pb.quantity from product p, product_bridge pb
42 | 		join cooking c on c.id = pb.part_of_id
43 | 		where p.id = pb.product_id
44 | 		
45 | --	select add recursive part
46 | )
47 | 
48 | select * FROM cooking;
49 | 
50 | insert into product(id, is_primary, name)
51 | values (3, true, 'cheese'),
52 | (13, false, 'cheesy pork')
53 | 


--------------------------------------------------------------------------------
/miscellaneous/food deliveries/Lunch-V.sql:
--------------------------------------------------------------------------------
 1 | create table ingredients(
 2 | 	id serial primary key,
 3 | 	name text not null
 4 | );
 5 | 
 6 | create table meal2ingredient(
 7 | 	id serial primary key,
 8 | 	ingredient_id int references ingredients(id),
 9 | 	meal_id int references meals(id)
10 | );
11 | 
12 | create table meals(
13 | 	id serial primary key,
14 | 	name text not null
15 | );
16 | 
17 | create table meal2meal(
18 | 	id serial primary key, 
19 | 	f_meal_id int references meals(id),
20 | 	s_meal_id int references meals(id)
21 | );
22 | 
23 | insert into ingredients (name) values ('pork'),
24 | 									  ('chicken'),
25 | 									  ('tomato'),
26 | 									  ('potato'),
27 | 									  ('cheese');
28 | 
29 | select * from ingredients;
30 | 
31 | insert into meals (name) values ('steak'),
32 | 								('fried cheese'),
33 | 								('burger');
34 | 
35 | select * from meals;
36 | 
37 | insert into meal2ingredient ( meal_id, ingredient_id) values (1 , 1), 
38 | 									  						 (2 , 5),
39 | 									  						 (3 , 4);
40 | 
41 | 
42 | insert into meal2meal (f_meal_id, s_meal_id) values (3 , 2),
43 | (3 , 1);
44 | 									  						
45 | 


--------------------------------------------------------------------------------
/miscellaneous/foreign data.sql:
--------------------------------------------------------------------------------
 1 | create extension file_fdw;
 2 | create server file_server foreign data wrapper file_fdw;
 3 | 
 4 | -- Attach file eurofxref-hist.csv (ECB exchange rate history) as a foreign table
 5 | -- https://www.ecb.europa.eu/stats/eurofxref/eurofxref-hist.zip
 6 | create foreign table ecb_forex
 7 | (
 8 |  "Date" date,
 9 |  USD numeric, JPY numeric, BGN numeric, CYP numeric, CZK numeric, DKK numeric, EEK numeric,
10 |  GBP numeric, HUF numeric, LTL numeric, LVL numeric, MTL numeric, PLN numeric, ROL numeric,
11 |  RON numeric, SEK numeric, SIT numeric, SKK numeric, CHF numeric, ISK numeric, NOK numeric,
12 |  HRK numeric, RUB numeric, TRL numeric, TRY numeric, AUD numeric, BRL numeric, CAD numeric,
13 |  CNY numeric, HKD numeric, IDR numeric, ILS numeric, INR numeric, KRW numeric, MXN numeric,
14 |  MYR numeric, NZD numeric, PHP numeric, SGD numeric, THB numeric, ZAR numeric, dummy text
15 | )
16 | server file_server
17 | options (
18 |  filename 'C:/foreign_data/eurofxref-hist.csv',
19 |  format 'csv', delimiter ',', null 'N/A', header 'true'
20 | );
21 | 
22 | -- Query data with plain SQL
23 | -- TRY stands for turkish lira
24 | select "Date", TRY
25 | from ecb_forex
26 | where TRY is not null order by "Date";
27 | 


--------------------------------------------------------------------------------
/miscellaneous/notifications/listener.php:
--------------------------------------------------------------------------------
 1 |  exec("LISTEN {$argv[1]};");
 5 |   echo "Listening channel {$argv[1]} ...".PHP_EOL;
 6 | 
 7 |   while(true)
 8 |     if ($res = $conn -> pgsqlGetNotify(PDO::FETCH_ASSOC, 500)) {
 9 |       $msg_data = json_decode($res['payload']);
10 | 
11 |       // That's all about listening. Some "business logic" follows
12 |       if ($msg_data -> v < 1000) continue;
13 |       if ($msg_data -> v >= 100000) $msg_template = 'A huge one, V is %d, ID is %d';
14 |       elseif ($msg_data -> v >= 10000) $msg_template = 'A large one, V is %d, ID is %d';
15 |       else $msg_template = 'Big fish, V is %d, ID is %d';
16 |       echo sprintf($msg_template, $msg_data -> v, $msg_data -> id).PHP_EOL;
17 |     }
18 | }
19 | else echo 'Error: syntax';
20 | 


--------------------------------------------------------------------------------
/miscellaneous/notifications/listeners.md:
--------------------------------------------------------------------------------
  1 | # Notify receivers
  2 | 
  3 | ## IMPORTANT
  4 | - add the ip of the machine that will receive the notifications in the `pg_hba.conf` file
  5 | 
  6 | ## Python
  7 | ```python
  8 | import psycopg2
  9 | import select
 10 | 
 11 | conn = psycopg2.connect("dbname=postgres user=postgres password=1234 host=192.168.1.203 port=5432")
 12 | conn.autocommit = True 
 13 | 
 14 | cur = conn.cursor()
 15 | cur.execute("LISTEN rita;")
 16 | 
 17 | print("Waiting for notifications on channel 'test_chan'...")
 18 | 
 19 | while True:
 20 |         select.select([conn], [], [])
 21 |         conn.poll()
 22 |         while conn.notifies:
 23 |             notify = conn.notifies.pop()
 24 |             print("Got NOTIFY:", notify.pid, notify.channel, notify.payload)
 25 | ```
 26 | 
 27 | ## Ruby
 28 | ```ruby
 29 | #!/usr/bin/env ruby
 30 | require 'rubygems'
 31 | require 'pg'
 32 | 
 33 | # adjust these also
 34 | begin
 35 |   conn = PG.connect(
 36 |     dbname:   'postgres',
 37 |     user:     'postgres',
 38 |     password: '1234',
 39 |     host:     '192.168.1.203',
 40 |     port:     5432
 41 |   )
 42 | 
 43 | # IMPORTANT change channel name also:
 44 |   conn.exec("LISTEN rita;")
 45 |   puts "Waiting for notifications on channel 'mychannel'..."
 46 | 
 47 |   loop do
 48 |     conn.wait_for_notify do |channel, pid, payload|
 49 |       puts "Received notification on #{channel}: #{payload}"
 50 |     end
 51 |   end
 52 | 
 53 | rescue PG::Error => e
 54 |   puts "An error occurred: #{e.message}"
 55 | # toni beshe tuk
 56 | ensure
 57 |   conn.close if conn
 58 | end
 59 | ```
 60 | 
 61 | ## C++
 62 | ```cpp
 63 | #include 
 64 | #include 
 65 | #include 
 66 | 
 67 | #include 
 68 | #include 
 69 | 
 70 | int main()
 71 | {
 72 |     const auto db_name = "postgres";
 73 |     const auto user = "postgres";
 74 |     const auto password = "postgres";
 75 |     const auto channel_name = "rita";
 76 | 
 77 |     const auto conn_info = std::format("dbname={} user={} password={}", db_name, user, password);
 78 |     PGconn*    conn      = PQconnectdb(conn_info.c_str());
 79 | 
 80 |     if (PQstatus(conn) != CONNECTION_OK)
 81 |     {
 82 |         std::println("Connection to database failed: {}", PQerrorMessage(conn));
 83 |         PQfinish(conn);
 84 |         return 1;
 85 |     }
 86 | 
 87 |     std::println("Connected to database");
 88 | 
 89 |     const auto listen_cmd   = std::format("LISTEN {};", channel_name);
 90 | 
 91 |     PGresult* res = PQexec(conn, listen_cmd.c_str());
 92 | 
 93 |     if (PQresultStatus(res) != PGRES_COMMAND_OK)
 94 |     {
 95 |         std::println("LISTEN command failed: {}", PQerrorMessage(conn));
 96 |         PQclear(res);
 97 |         PQfinish(conn);
 98 |         return 1;
 99 |     }
100 |     PQclear(res);
101 | 
102 |     std::println("Listening on channel: {}", channel_name);
103 | 
104 |     while (true)
105 |     {
106 |         PQconsumeInput(conn);
107 | 
108 |         PGnotify* notify;
109 |         while ((notify = PQnotifies(conn)) != nullptr)
110 |         {
111 |             std::println("Notification received:\n"
112 |                          "\t{}\n"
113 |                          "\t{}\n"
114 |                          "\t{}",
115 |                          notify->relname,
116 |                          notify->be_pid,
117 |                          notify->extra ? notify->extra : "NULL");
118 | 
119 |             PQfreemem(notify);
120 |         }
121 | 
122 |         usleep(100000);
123 |     }
124 | 
125 |     PQfinish(conn);
126 | }
127 | ```
128 | 


--------------------------------------------------------------------------------
/miscellaneous/notifications/publisher.sql:
--------------------------------------------------------------------------------
 1 | create table tests.notifier 
 2 | (
 3 |   id integer primary key generated always as identity,
 4 |   v integer
 5 | );
 6 | 
 7 | create or replace function tests.notifier_tf() returns trigger language plpgsql as
 8 | $$
 9 | begin
10 |   if new.v >= 1000 then
11 |     perform pg_notify(coalesce(TG_ARGV[0], 'general'), to_json(new)::text);
12 |   end if;
13 |   return null;
14 | end;
15 | $$;
16 | 
17 | create trigger notifier_t after insert
18 | on tests.notifier for each row
19 | execute function tests.notifier_tf('rita');
20 | 
21 | -- Unit test
22 | insert into tests.notifier (v)
23 | values (10), (1001), (10001), (200000);
24 | 


--------------------------------------------------------------------------------
/miscellaneous/notifications/readme.md:
--------------------------------------------------------------------------------
1 | ### A sample SQL notifier and a few CLI listeners in different languages
2 | ![image](https://github.com/user-attachments/assets/1c0c8a05-d9c7-460c-8685-cde3098de01e)  
3 | (Listener has been stopped by Ctrl-C)  
4 | > [!NOTE]
5 | > the notification channel name is `rita`
6 | 


--------------------------------------------------------------------------------
/miscellaneous/partitioning.sql:
--------------------------------------------------------------------------------
 1 | create table person 
 2 | (
 3 |   person_name text,
 4 |   person_weight integer
 5 | )
 6 | partition by range(person_weight);
 7 | 
 8 | -- set "light" lower bound to unbounded min
 9 | create table light partition of person
10 | for values from (minvalue) to (50);
11 | 
12 | create table medium partition of person
13 | for values from (51) to (90);
14 | 
15 | create table heavy partition of person
16 | for values from (91) to (1000); -- not very nice
17 | 
18 | insert into person values 
19 | ('Stefan', 95), ('Samuil', 60), ('Borimir', 70), ('Rita', 6);
20 | 
21 | -- change "heavy" upper bound from 1000 to unbounded max
22 | alter table person detach partition heavy;
23 | alter table person attach partition heavy
24 | for values from (91) to (maxvalue);
25 | 
26 | select * from person;
27 | select * from light;
28 | select * from medium;
29 | select * from heavy;
30 | 
31 | create or replace function get_partitions(parent text) 
32 | returns table(schema_name text, table_name text) language sql as
33 | $$
34 | select nsp.nspname, tbl.relname
35 | from pg_catalog.pg_namespace nsp
36 |   join pg_catalog.pg_class tbl
37 |   on nsp.oid = tbl.relnamespace
38 | where tbl.oid in (
39 |   select inhrelid 
40 |   from pg_catalog.pg_inherits
41 |   where  inhparent = parent::regclass
42 | )
43 | $$;
44 | 
45 | select * from get_partitions('public.person');
46 | 
47 | -- Result:
48 | -- schema_name|table_name|
49 | -- -----------+----------+
50 | -- public     |medium    |
51 | -- public     |heavy     |
52 | -- public     |light     |
53 | 


--------------------------------------------------------------------------------
/miscellaneous/query rettype.py:
--------------------------------------------------------------------------------
 1 | # ----------------------------------------------------------
 2 | # Resolve SQL query return type for type-safety use
 3 | # PostgreSQL flavour. May differ for other RDBMS
 4 | # S.Stefanov, Nov 2024
 5 | # ----------------------------------------------------------
 6 | 
 7 | import json
 8 | import psycopg
 9 | 
10 | def query_rettype(connectionstring, query):
11 |   retval = {}
12 |   try:
13 |     with psycopg.connect(connectionstring) as conn:
14 |       with conn.cursor() as stmt:
15 |         stmt.execute(f'SELECT * from ({query}) as t limit 0')
16 |         retval = {
17 |           'status': True,
18 |           'value': [{'name':x.name, 'type_code':x.type_code} for x in stmt.description]
19 |          }
20 |   except Exception as err:
21 |     retval = {'status': False, 'value': str(err)}
22 |   return json.dumps(retval, indent = 2)
23 | 
24 | # Unit test
25 | # ----------------------------------------------------------
26 | # CONNECTIONSTRING = 'host=localhost port=5432 dbname=postgres user=postgres password=TheLongPassword'
27 | # sql = 'select * from tests.the_table'
28 | # print (query_rettype(CONNECTIONSTRING, sql))
29 | # sql = 'select bang now! * from tests.the_table'
30 | # print (query_rettype(CONNECTIONSTRING, sql))
31 | 
32 | # Get type name by type_code
33 | # ----------------------------------------------------------
34 | # select 
35 | #   oid as type_code,
36 | #   typname as type_name,
37 | #   typlen as type_length
38 | # from pg_catalog.pg_type 
39 | # where oid = :type_code;
40 | 
41 | 


--------------------------------------------------------------------------------
/miscellaneous/replication.md:
--------------------------------------------------------------------------------
 1 | ## Setup logical replication
 2 | ### (it turned out to be more tricky than expected)
 3 | 
 4 | ### A few bits of administration
 5 | ### On the publisher:
 6 | - Edit `postgresql.conf`
 7 | ```
 8 | wal_level = logical
 9 | max_replication_slots = 10
10 | max_wal_senders = 10
11 | listen_addresses = '*'
12 | ```
13 | - Edit `pg_hba.conf`
14 | ```
15 | host  replication  all     0.0.0.0/0        scram-sha-256
16 | host  replication  all     ::0/0            scram-sha-256
17 | ```
18 | - Restart PostgreSQL
19 | - Add a firewall rule to allow access to PostgreSQL port (ususally `5432`)
20 | 
21 | 
22 | ### On the subscriber:  
23 | - Edit `postgresql.conf`
24 | ```
25 | hot_standby = on
26 | ```
27 | - Restart PostgreSQL
28 | 
29 | ### And finally SQL
30 | ### On the publisher:
31 | ```sql
32 | -- create schema if not exists rep;
33 | -- drop table if exists rep.r_table;
34 | 
35 | create table rep.r_table (
36 |  id integer primary key generated by default as identity, 
37 |  t text, n numeric,
38 |  b boolean default false
39 | );
40 | 
41 | insert into rep.r_table (t, n) values ('Initial record(s)', 1);
42 | select * from rep.r_table;
43 | 
44 | -- drop publication if exists tues_pub;
45 | 
46 | CREATE PUBLICATION tues_pub
47 | FOR TABLE rep.r_table -- , second_table, third_table, ...
48 | WITH (publish = 'insert, update, delete');
49 | 
50 | insert into rep.r_table (n, t) 
51 | with t(n) as 
52 | (
53 |  select random (100, 2000)
54 |  from generate_series(1, 1000)
55 | )
56 | select n, to_char(n, 'FMRN') t
57 | from t;
58 | 
59 | update rep.r_table set b = true where id = 3;
60 | ```
61 | ### On the subscriber:  
62 | ```sql
63 | -- create table if not exists rep;
64 | -- drop table if exists rep.r_table;
65 | 
66 | create table rep.r_table (
67 |  id integer primary key generated by default as identity,
68 |  t text, n numeric,
69 |  b boolean default false
70 | );
71 | 
72 | 
73 | -- drop subscription if exists tues_sub;
74 | 
75 | CREATE SUBSCRIPTION tues_sub
76 | CONNECTION 'host=192.168.1.8 port=5432 dbname=postgres user=postgres password=********'
77 | PUBLICATION tues_pub;
78 | 
79 | select * from rep.r_table order by id;
80 | ```
81 | ### Last but not least  
82 | > [!IMPORTANT]    
83 | > See also [REPLICA IDENTITY](https://www.postgresql.org/docs/current/sql-altertable.html#SQL-ALTERTABLE-REPLICA-IDENTITY) 
84 | 


--------------------------------------------------------------------------------
/miscellaneous/session.variables.sql:
--------------------------------------------------------------------------------
 1 | -- Session variables' wrappers
 2 | -- S. Stefanov, June-2025
 3 | 
 4 | create or replace function getv(varname text)
 5 | returns text language plpgsql as $$
 6 | begin
 7 | 	return current_setting('user_session_var__.'||varname);
 8 | exception when others then
 9 | 	return null;
10 | end;
11 | $$;
12 | 
13 | create or replace function setv(varname text, val text)
14 | returns text language sql as $$
15 | 	select set_config('user_session_var__.'||varname, val, false);
16 | $$;
17 | 


--------------------------------------------------------------------------------
/miscellaneous/table definitions.sql:
--------------------------------------------------------------------------------
 1 | create table meteo_readings
 2 | (
 3 | reading_time timestamp not null default now(), 
 4 | reading_temp numeric, 
 5 | reading_humidity numeric, 
 6 | reading_rainfall numeric, 
 7 | reading_windspeed numeric, 
 8 | reading_illumination numeric,
 9 | reading_wind_angle numeric,
10 | reading_pressure numeric
11 | );
12 | 
13 | INSERT INTO meteo_readings (reading_time, reading_rainfall, reading_temp, reading_illumination, reading_windspeed)
14 | VALUES
15 | ('2025-01-27 06:00:00', 0.0,  18, 300, 5),
16 | ('2025-01-27 14:00:00', 0.0,  22, 800, 7),
17 | ('2025-01-27 22:00:00', 0.0,  20, 400, 6),
18 | ('2025-01-28 06:00:00', 5.0,  17, 250, 10),
19 | ('2025-01-28 14:00:00', 0.0,  23, 850, 12),
20 | ('2025-01-28 22:00:00', 0.0,  19, 350, 9),
21 | ('2025-01-29 06:00:00', 0.0,  16, 200, 8),
22 | ('2025-01-29 14:00:00', 10.0, 24, 900, 15),
23 | ('2025-01-29 22:00:00', 0.0,  21, 450, 11),
24 | ('2025-01-30 06:00:00', 0.0,  19, 220, 7),
25 | ('2025-01-30 14:00:00', 0.0,  25, 950, 14),
26 | ('2025-01-30 22:00:00', 0.0,  22, 500, 10),
27 | ('2025-01-30 06:00:00', 7.5,  21, 220, 7),
28 | ('2025-01-30 14:00:00', 0.0,  26, 950, 14),
29 | ('2025-01-30 22:00:00', 2.1,  24, 500, 10);
30 | 
31 | create or replace function pg_temp.randomstring(nchars integer)
32 | returns text language sql as
33 | $$
34 |  select lpad((random() * (10^nchars))::integer::text, nchars, '0');
35 | $$;
36 | 


--------------------------------------------------------------------------------
/miscellaneous/test.prep.II.sql:
--------------------------------------------------------------------------------
 1 | -- Create a query on "test_table" below that yields 3 columns: vdate, value and ballance for each day for the last two months
 2 | 
 3 | create table if not exists test_table 
 4 | (
 5 |   id integer primary key not null generated by default as identity,
 6 |   vdate date not null, -- value date
 7 |   value numeric not null, -- deposit/withdrawal
 8 |   details jsonb not null default '{}'
 9 | );
10 | 
11 | insert into test_table (value, details, vdate)
12 | values (1000, '{"status":"inititial ballance"}', current_date - 60);
13 | 
14 | insert into test_table (vdate, value)
15 | select current_date - random (1, 59) as vdate, random (-100, 100) as value
16 | from generate_series(1, 20);
17 | 
18 | select * from test_table;
19 | 
20 | with cl_date as (
21 | 	select generate_series(current_date - 60, current_date, interval '1 day'):: date as vdate
22 | ),
23 | daily_values as (
24 | 	select vdate, coalesce(value, 0) as value from cl_date left outer join test_table using (vdate)
25 | ),
26 | res as (
27 | 	select vdate, value, 
28 | 	sum(value) over (order by vdate rows between unbounded preceding and current row) balance 
29 | 	from daily_values
30 | )
31 | select json_agg(final order by vdate) from res as final;
32 | 
33 | 
34 | -- TODO: 
35 | --  write a query that yields 3 columns: 
36 | --  vdate, value and ballance
37 | --  for EACH of the last 60 days
38 | 
39 | -- cleanup when done
40 | drop table if exists test_table;
41 | 


--------------------------------------------------------------------------------
/miscellaneous/test.prep.sql:
--------------------------------------------------------------------------------
 1 | -- Create a query on "test_table" below that yields 3 columns: vdate, value and ballance for each day for the last two months
 2 | 
 3 | create table if not exists test_table 
 4 | (
 5 |   id integer primary key not null generated by default as identity,
 6 |   vdate date not null, -- value date
 7 |   value numeric not null, -- deposit/withdrawal
 8 |   details jsonb not null default '{}'
 9 | );
10 | 
11 | insert into test_table (value, details, vdate)
12 | values (1000, '{"status":"inititial ballance"}', current_date - 60);
13 | 
14 | insert into test_table (vdate, value)
15 | select current_date - random (1, 59) as vdate, random (-100, 100) as value
16 | from generate_series(1, 20);
17 | 
18 | select * from test_table;
19 | 
20 | -- TODO: 
21 | --  write a query that yields 3 columns: 
22 | --  vdate, value and ballance
23 | --  for EACH of the last 60 days
24 | 
25 | -- cleanup when done
26 | drop table if exists test_table;
27 | 


--------------------------------------------------------------------------------
/miscellaneous/three utility functions.sql:
--------------------------------------------------------------------------------
 1 | -- find_* unctions use a correlated scalar subquery
 2 | --------------------------------------------------
 3 | 
 4 | -- drop function if exists find_routine;
 5 | create or replace function find_routine (partial_name text)
 6 | returns table (
 7 | 	routine_full_name text, 
 8 | 	routine_type text, 
 9 | 	return_type text, 
10 | 	arguments text[], 
11 | 	routine_body text
12 | ) as $function$
13 |  select
14 |     format('%I.%I', routine_schema, routine_name),
15 |     routine_type, data_type,
16 |     (
17 |      select array_agg(format('%s %I %s', 
18 |               parameter_mode,
19 |               coalesce(parameter_name, '$'), -- anonymous positional arguments
20 |               data_type
21 |             ) order by ordinal_position)
22 |      from information_schema.parameters as p
23 |      where p.specific_name = r.specific_name
24 |     ),
25 |     routine_definition
26 |  from information_schema.routines as r
27 |  where routine_name ~* partial_name
28 |    and routine_schema not in ('information_schema', 'pg_catalog') 
29 |  order by routine_name, routine_schema;
30 | $function$ language sql;
31 | 
32 | --------------------------------------------------
33 | 
34 | -- drop function if exists find_table;
35 | create or replace function find_table (partial_name text)
36 | returns table (
37 |     table_full_name text, 
38 |     table_type text, 
39 |     columns text[] 
40 | ) as $function$
41 |  select
42 |     format('%I.%I', table_schema, table_name),
43 |     table_type, 
44 |     (
45 |      select array_agg(concat_ws(' ',
46 |          format('%I', column_name),
47 |          data_type,
48 |          case when is_nullable = 'NO' then 'not null' end,
49 |          'default ' || column_default
50 |         ) order by ordinal_position)
51 |      from information_schema.columns as c
52 |      where t.table_name = c.table_name 
53 |        and t.table_schema = c.table_schema
54 |     ) 
55 |  from information_schema.tables as t
56 |  where table_name ~* partial_name
57 |    and table_schema not in ('information_schema', 'pg_catalog')
58 |  order by table_name, table_schema;
59 | $function$ language sql;
60 | 
61 | --------------------------------------------------
62 | -- Use pgcrypto extension functions to validate the JWT signature (pos. 3)
63 | 
64 | create or replace function decode_jwt(jwt text)
65 | returns table (pos integer, contents text) language sql immutable as
66 | $$
67 | with parts as (
68 |   select * from regexp_split_to_table(jwt, '\.') with ordinality as t(x, pos)
69 | )
70 | select pos,
71 |   case when pos = 3 then x
72 |   else convert_from(decode(rpad(translate(x, '-_', '+/'), 4*((length(x)+3)/4), '='), 'base64'), 'utf-8')
73 |   end
74 | from parts order by pos;
75 | $$;
76 | 
77 | -- Unit test -------------------------------------
78 | 
79 | select * from decode_jwt('eyJhbGciOiJIUzI1NiIsInR5cCI6IkpXVCJ9.eyJzdWIiOiIxMjM0NTY3ODkwIiwibmFtZSI6IkpvaG4gRG9lIiwiaWF0IjoxNTE2MjM5MDIyfQ.SflKxwRJSMeKKF2QT4fwpMeJf36POk6yJV_adQssw5c');
80 | 


--------------------------------------------------------------------------------
/miscellaneous/Количествено-стойностна сметка/Teams-XI.xlsx:
--------------------------------------------------------------------------------
https://raw.githubusercontent.com/stefanov-sm/Database-XI/3d4c68199bb9cf0bee3567f51180b3834996a164/miscellaneous/Количествено-стойностна сметка/Teams-XI.xlsx


--------------------------------------------------------------------------------
/parameterization/in_list.ora.pls:
--------------------------------------------------------------------------------
 1 | -- https://dbfiddle.uk/_9Xjjnxj
 2 | 
 3 | create or replace function in_range_list(vx number, range_list varchar2, range_delim varchar2 default '-') return varchar2 as
 4 |  retval varchar2(5);
 5 |  exclude integer;
 6 |  v_range_list varchar2(1024);
 7 | 
 8 |  RV_YES constant varchar2(5) := 'TRUE';
 9 |  RV_NO  constant varchar2(5) := 'FALSE';
10 | 
11 | begin
12 |  if range_list is null then return RV_YES; end if;
13 |  if vx is null then return RV_YES; end if;
14 | 
15 |  if regexp_like(range_list, '^(<>|><|!)') then
16 |     exclude := 1;
17 |     v_range_list := ltrim(range_list, '<>! ');
18 |  else
19 |     exclude := 0;
20 |     v_range_list := range_list;
21 |  end if;
22 | 
23 |  with t(rli) as
24 |  (
25 |    select regexp_substr(v_range_list, '[^,]+', 1, level) from dual
26 |    connect by level <= length(v_range_list) - length(replace(v_range_list, ',')) + 1
27 |  )
28 |  select case when exists
29 |  (
30 |    select 1 from t
31 |    where instr(rli, range_delim) = 0 and cast(rli as number) = vx -- scalar
32 |    or vx between cast(substr(rli, 1, instr(rli,range_delim) - 1) as number) -- range
33 |              and cast(substr(rli, instr(rli,range_delim) + length(range_delim)) as number)
34 |  ) then RV_YES else RV_NO end
35 |  into retval from dual;
36 | 
37 |  if exclude = 1 then 
38 |    select decode(retval, RV_YES, RV_NO, RV_NO, RV_YES) into retval from dual;
39 |  end if;
40 |  return retval;
41 | end;
42 | /
43 | 
44 | create or replace function in_str_list(vs varchar2, str_list varchar2) return varchar2 as
45 |  retval varchar2(5);
46 |  exclude integer;
47 |  v_str_list varchar2(1024);
48 | 
49 |  RV_YES constant varchar2(5) := 'TRUE';
50 |  RV_NO  constant varchar2(5) := 'FALSE';
51 | 
52 | begin
53 |  if str_list is null then return RV_YES; end if;
54 |  if vs is null then return RV_NO; end if;
55 | 
56 |  if regexp_like(str_list, '^(<>|><|!)') then
57 |     exclude := 1;
58 |     v_str_list := ltrim(str_list, '<>! ');
59 |  else
60 |     exclude := 0;
61 |     v_str_list := str_list;
62 |  end if;
63 | 
64 |  with t(sli) as
65 |  (
66 |    select regexp_substr(v_str_list, '[^,]+', 1, level) from dual
67 |    connect by level <= length(v_str_list) - length(replace(v_str_list, ',')) + 1
68 |  )
69 |  select case when exists (select 1 from t where vs = sli) then RV_YES else RV_NO end 
70 |  into retval
71 |  from dual;
72 | 
73 |  if exclude = 1 then 
74 |    select decode(retval, RV_YES, RV_NO, RV_NO, RV_YES) into retval from dual;
75 |  end if;
76 |  return retval;
77 | end;
78 | /
79 | 
80 | select in_range_list(5, '1,2,3') a,
81 |        in_range_list(20, '1, 2, 3, -8 .. 29,121', '..') b,
82 |        in_range_list(99, null) c,
83 |        in_range_list(9, '9') d,
84 |        in_range_list(5, '!1,2,3') e,
85 |        in_range_list(6, '<>1,2,3,5 - 15') f,
86 |        in_range_list(null, '1,2,3,5 - 15') g,
87 |        in_range_list(null, null) h,
88 |        in_str_list('ALA', 'ALA,BALA') i,
89 |        in_str_list('ALA', '<>ALAS,BALAS') j
90 | from dual;
91 | 


--------------------------------------------------------------------------------
/parameterization/parameterization.sql:
--------------------------------------------------------------------------------
  1 | -- ---------------------------------------------------------------------
  2 | create or replace function par.in_range_list(target numeric, arg_range_list text)
  3 | returns boolean language sql immutable as $function$
  4 | -- Valid range list syntax: 'NULL' or '1' or '1,2,3' or '1,2..5,7..23,100'
  5 | select (arg_range_list is null)
  6 | or exists
  7 | (
  8 |   select from unnest(string_to_array(arg_range_list, ',')) as r 
  9 |   where case
 10 |     when r !~ '\.\.' then (target = r::numeric)  -- single value
 11 |     else (target between split_part(r, '..', 1)::numeric 
 12 |                      and split_part(r, '..', 2)::numeric)
 13 |   end
 14 | )
 15 | $function$;
 16 | -- ---------------------------------------------------------------------
 17 | create table if not exists par.item
 18 | (
 19 |  id serial primary key not null,
 20 |  name text,
 21 |  category integer check (category in (1, 2, 3, 4)), -- тип: (1) плод, (2) зеленчук, (3) вариво, (4) друго
 22 |  shelf_life integer check (shelf_life in (1, 2, 3)) -- трайност: (1) малка, (2) средна, (3) голяма
 23 | );
 24 | -- ---------------------------------------------------------------------
 25 | create table if not exists par.sales
 26 | (
 27 |  id serial primary key not null,
 28 |  item_id integer references par.item(id),
 29 |  sales_date date,
 30 |  quantity numeric
 31 | );
 32 | -- ---------------------------------------------------------------------
 33 | create table if not exists par.param
 34 | (
 35 |  id serial primary key not null,
 36 |  description_a text,
 37 |  code_a text,
 38 |  description_b text,
 39 |  code_b text,
 40 |  notes text
 41 | );
 42 | -- ---------------------------------------------------------------------
 43 | insert into par.item (name, category, shelf_life)
 44 | values
 45 |  ('ябълка', 1, 2),       ('круша', 1, 2),         ('портокал', 1, 2),    ('мандарина', 1, 2),
 46 |  ('банан', 1, 1),        ('нар', 1, 2),           ('диня', 1, 2),        ('пъпеш', 1, 2),
 47 |  ('ягода', 1, 1),        ('череша', 1, 1),        ('слива', 1, 2),       ('кокосов орех', 1, 3),
 48 |  ('дюля', 1, 2),         ('тиква', 1, 2),         ('грозде', 1, 2),      ('орех', 4, 3),
 49 |  ('фастък', 4, 3),       ('лешник', 4, 3),        ('зелен лук', 2, 1),   ('зелен чесън', 2, 1),
 50 |  ('маруля', 2, 1),       ('магданоз', 2, 1),      ('копър', 2, 1),       ('стар лук', 2, 3),
 51 |  ('стар чесън', 2, 3),   ('краставица', 2, 2),    ('тиквичка', 2, 2),    ('патладжан', 2, 2),
 52 |  ('домат', 2, 2),        ('спанак', 2, 1),        ('зелен фасул', 2, 2), ('грах', 2, 2),
 53 |  ('зелена чушка', 2, 2), ('червена чушка', 2, 2), ('сушена чушка', 2, 3),
 54 |  ('боб', 3, 3),          ('леща', 3, 3);
 55 | -- ---------------------------------------------------------------------
 56 | insert into par.param (description_a,code_a,description_b,code_b,notes) values
 57 |  ('category', '2',   'shelf_life', '2',   '3.Зеленчуци със средна трайност'),
 58 |  ('category', '2',   'shelf_life', '1',   '1.Зеленчуци с малка трайност'),
 59 |  ('category', '3',   'shelf_life', '3',   '5.Варива с голяма трайност'),
 60 |  ('category', '1',   'shelf_life', '1',   '2.Плодове с малка трайност'),
 61 |  ('category', '4',   'shelf_life', '3',   '6.Други с голяма трайност'),
 62 |  ('category', '3,4', 'shelf_life', NULL,  '7.Разни други'),
 63 |  ('category', '1,2', 'shelf_life', NULL,  '8.Плодове и зеленчуци'),
 64 |  ('category', '1',   'shelf_life', '2,3', '4.Плодове със средна и голяма трайност'),
 65 |  ('category', NULL,  'shelf_life', '1',   '9.Всички с малка трайност');
 66 | -- ---------------------------------------------------------------------
 67 | select id, name "име", 
 68 |  (array['плод','зеленчук','вариво','друго'])[category] "тип",
 69 |  (array['малка','средна','голяма'])[shelf_life] "трайност"
 70 | from par.item;
 71 | -- ---------------------------------------------------------------------
 72 | truncate table par.sales;
 73 | insert into par.sales (item_id, sales_date, quantity)
 74 |  select random(1, 37), '2025-05-01'::date + random(1, 61), random(1, 100)::numeric / 20
 75 |  from generate_series (1, 500000);
 76 | -- ---------------------------------------------------------------------
 77 | select sales.id, sales_date "дата", quantity "количество", name "име", category,
 78 |        (array['плод','зеленчук','вариво','друго'])[category] "тип",
 79 |        (array['малка','средна','голяма'])[shelf_life] "трайност"
 80 | from par.sales
 81 | join par.item on item_id = item.id;
 82 | 
 83 | -- ---------------------------------------------------------------------
 84 | -- Here it is - a complex report made flexible and simple
 85 | -- ---------------------------------------------------------------------
 86 | select param.notes, count(*), sum(quantity)
 87 | from par.sales join par.item on sales.item_id = item.id
 88 | 
 89 | join par.param on 
 90 |      par.in_range_list(category,   param.code_a)
 91 |  and par.in_range_list(shelf_life, param.code_b)
 92 | 
 93 |  where sales_date between '2025-05-01' and '2025-05-31'
 94 | group by param.id
 95 | order by substring(notes from '^\d+')::numeric;
 96 | 
 97 | /*
 98 | notes                                 |count |sum      |
 99 | --------------------------------------+------+---------+
100 | 1.Зеленчуци с малка трайност          | 39836|100685.25|
101 | 2.Плодове с малка трайност            | 19861| 50051.05|
102 | 3.Зеленчуци със средна трайност       | 53069|133674.35|
103 | 4.Плодове със средна и голяма трайност| 80066|202363.65|
104 | 5.Варива с голяма трайност            | 13135| 33226.25|
105 | 6.Други с голяма трайност             | 19954| 50597.75|
106 | 7.Разни други                         | 33089| 83824.00|
107 | 8.Плодове и зеленчуци                 |212447|536535.55|
108 | 9.Всички с малка трайност             | 59697|150736.30|
109 | 
110 | insert into par.param (description_a,code_a,description_b,code_b,notes)
111 | values
112 |  ('category', null, 'shelf_life', null, '10. Всичко продадено');
113 | 
114 | */
115 | 
116 | 


--------------------------------------------------------------------------------
/parameterization/readme.md:
--------------------------------------------------------------------------------
1 | ## "Parameterization"
2 | ### Querying & reporting magic by Нико Попов  
3 | ---
4 | > [!NOTE]  
5 | > This is an OLAP method, not to be used in OLTP workloads
6 | 


--------------------------------------------------------------------------------
/presentations/jwtfunc.sql:
--------------------------------------------------------------------------------
 1 | create extention if not exists pgcrypto;
 2 | 
 3 | create or replace function decode_jwt(jwt text, secret text)
 4 | returns table (pos integer, contents text, valid_signature boolean) language sql immutable as
 5 | $$
 6 | with parts as (
 7 |   select * from regexp_split_to_table(jwt, '\.') with ordinality as t(x, pos)
 8 | ), decoded_parts AS (
 9 |   select pos,
10 |          case when pos = 3 then x
11 |            else convert_from(decode(rpad(translate(x, '-_', '+/'), 4 * ((length(x) + 3) / 4), '='), 'base64'), 'utf-8')
12 |          end as contents
13 |   from parts
14 | ), signature_check as (
15 |   select
16 |     (select string_agg(x, '.') from parts where pos in (1,2)) as signing_input, -- Header + Payload
17 |     decode(rpad(translate((select contents from decoded_parts where pos = 3), '-_', '+/'), 4 * ((length((select contents from decoded_parts where pos = 3)) + 3) / 4), '='), 'base64') as signature, -- base64url -> base64 -> binary
18 |     (select contents::jsonb ->> 'alg' from decoded_parts where pos = 1) as algorithm -- read `alg` from header
19 | )
20 | SELECT d.pos, d.contents,
21 |        case 
22 |          when d.pos = 3 and algorithm = 'HS256' then 
23 |            encode(hmac(signing_input, secret, 'sha256'), 'base64') = encode(signature, 'base64')
24 |          when d.pos = 3 and algorithm = 'HS384' then 
25 |            encode(hmac(signing_input, secret, 'sha384'), 'base64') = encode(signature, 'base64')
26 |          when d.pos = 3 and algorithm = 'HS512' then 
27 |            encode(hmac(signing_input, secret, 'sha512'), 'base64') = encode(signature, 'base64')
28 |          else null
29 |        end as valid_signature
30 | from decoded_parts d
31 | left join signature_check sc on true
32 | order by d.pos;
33 | $$;
34 | 
35 | 
36 | 
37 | 
38 | 
39 | --hs256
40 | select * from decode_jwt(
41 |   'eyJhbGciOiJIUzI1NiIsInR5cCI6IkpXVCJ9.eyJzdWIiOiIxMjM0NTY3ODkwIiwibmFtZSI6IkpvaG4gRG9lIiwiYWRtaW4iOnRydWUsImlhdCI6MTUxNjIzOTAyMn0.KMUFsIDTnFmyG3nMiGM6H9FNFUROf3wh7SmqJp-QV30', 
42 |   'a-string-secret-at-least-256-bits-long'
43 | );
44 | 
45 | 
46 | 
47 | --hs384
48 | select * from decode_jwt(
49 |   'eyJhbGciOiJIUzM4NCIsInR5cCI6IkpXVCJ9.eyJzdWIiOiIxMjM0NTY3ODkwIiwibmFtZSI6IkpvaG4gRG9lIiwiYWRtaW4iOnRydWUsImlhdCI6MTUxNjIzOTAyMn0.owv7q9nVbW5tqUezF_G2nHTra-ANW3HqW9epyVwh08Y-Z-FKsnG8eBIpC4GTfTVU', 
50 |   'a-valid-string-secret-that-is-at-least-384-bits-long'
51 | );
52 | 
53 | 
54 | --hs512
55 | select * from decode_jwt(
56 |   'eyJhbGciOiJIUzUxMiIsInR5cCI6IkpXVCJ9.eyJzdWIiOiIxMjM0NTY3ODkwIiwibmFtZSI6IkpvaG4gRG9lIiwiYWRtaW4iOnRydWUsImlhdCI6MTUxNjIzOTAyMn0.ANCf_8p1AE4ZQs7QuqGAyyfTEgYrKSjKWkhBk5cIn1_2QVr2jEjmM-1tu7EgnyOf_fAsvdFXva8Sv05iTGzETg', 
57 |   'a-valid-string-secret-that-is-at-least-512-bits-long-which-is-very-long'
58 | );
59 | 
60 | 


--------------------------------------------------------------------------------
/presentations/recursive queries.pdf:
--------------------------------------------------------------------------------
https://raw.githubusercontent.com/stefanov-sm/Database-XI/3d4c68199bb9cf0bee3567f51180b3834996a164/presentations/recursive queries.pdf


--------------------------------------------------------------------------------